Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started

Reply
pankajsk83
Regular Visitor

Calculate overrides filter context only on date table but not from sales table

I am trying to understand how calculate overrides the filter context. Below, I have a very simple formula. The matrix visual at the top has the date from sales table. The one below has the data from the dates(calendar) table. Why does calculate override filter context only below and not in the one above? I was expecting the above table to also have the same values as below.

 

override.JPG

1 ACCEPTED SOLUTION
OwenAuger
Super User
Super User

Hi @pankajsk83 

The basic explanation is that filters apply to specific columns. Filters on 'Date'[Date] are distinct from filters on Sales[Order Date] even though there is a relationship between them.

 

This means that, when a filter argument for a particular column is specified in CALCULATE:

  • Any existing filter on that same column is replaced by the new filter.
  • Any existing filters on other columns remain in place, and are effectively "intersected" with the new filter.

Using your example, assuming no other filters exist:

  1. For the 2nd visual, 'Date'[Date] is on the rows of the visual.
    Let's consider the row with 'Date'[Date] = 2017-01-01.
    • Existing filter context in this row is a single filter 'Date'[Date] = 2017-01-01
    • New filter from CALCULATE is 'Date'[Date] IN { 2017-05-19, 2017-05-20 }
    • Since the New filter is on the same column as the Existing filter, the Existing filter is replaced.
    • The resulting filter context is therefore just 'Date'[Date] IN { 2017-05-19, 2017-05-20 }, and it will be the same on every row of the visual.
  2. For the 1st visual, Sales[Order Date] is on the rows of the visual.
    Let's consider the row with Sales[Order Date] = 2017-05-19.
    • Existing filter context in this row is a single filter Sales[Order Date] = 2017-05-19
    • New filter from CALCULATE is 'Date'[Date] IN { 2017-05-19, 2017-05-20 }
    • Since the New filter is on a different column from the Existing filter, both filters will be in effect when evaluating the first argument of CALCULATE.
    • The resulting filter context is therefore Sales[Order Date] = 2017-05-19 AND 'Date'[Date] IN { 2017-05-19, 2017-05-20 }.
    • Because of the relationship between Sales and 'Date' tables, the value of [Sales Amount] will be blank unless Sales[Order Date] from the current row of the visual is within the range 2017-05-19 to 2017-05-20, i.e. the two rows that are visible.

To avoid this kind of confusion, it is generally recommended to filter or group by columns of dimension tables only, not fact tables. In this particular case, I would suggest that Sales[Order Date] should be hidden and not included in any visuals, and instead just use columns of the 'Date' table (there may be exceptions to this).

 

Regards


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

View solution in original post

2 REPLIES 2
OwenAuger
Super User
Super User

Hi @pankajsk83 

The basic explanation is that filters apply to specific columns. Filters on 'Date'[Date] are distinct from filters on Sales[Order Date] even though there is a relationship between them.

 

This means that, when a filter argument for a particular column is specified in CALCULATE:

  • Any existing filter on that same column is replaced by the new filter.
  • Any existing filters on other columns remain in place, and are effectively "intersected" with the new filter.

Using your example, assuming no other filters exist:

  1. For the 2nd visual, 'Date'[Date] is on the rows of the visual.
    Let's consider the row with 'Date'[Date] = 2017-01-01.
    • Existing filter context in this row is a single filter 'Date'[Date] = 2017-01-01
    • New filter from CALCULATE is 'Date'[Date] IN { 2017-05-19, 2017-05-20 }
    • Since the New filter is on the same column as the Existing filter, the Existing filter is replaced.
    • The resulting filter context is therefore just 'Date'[Date] IN { 2017-05-19, 2017-05-20 }, and it will be the same on every row of the visual.
  2. For the 1st visual, Sales[Order Date] is on the rows of the visual.
    Let's consider the row with Sales[Order Date] = 2017-05-19.
    • Existing filter context in this row is a single filter Sales[Order Date] = 2017-05-19
    • New filter from CALCULATE is 'Date'[Date] IN { 2017-05-19, 2017-05-20 }
    • Since the New filter is on a different column from the Existing filter, both filters will be in effect when evaluating the first argument of CALCULATE.
    • The resulting filter context is therefore Sales[Order Date] = 2017-05-19 AND 'Date'[Date] IN { 2017-05-19, 2017-05-20 }.
    • Because of the relationship between Sales and 'Date' tables, the value of [Sales Amount] will be blank unless Sales[Order Date] from the current row of the visual is within the range 2017-05-19 to 2017-05-20, i.e. the two rows that are visible.

To avoid this kind of confusion, it is generally recommended to filter or group by columns of dimension tables only, not fact tables. In this particular case, I would suggest that Sales[Order Date] should be hidden and not included in any visuals, and instead just use columns of the 'Date' table (there may be exceptions to this).

 

Regards


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

Owen, thank you this. Very crisp and clear explanation. Plus a good lesson here to group by columns of DIM tables only. 

Helpful resources

Announcements
Sept PBI Carousel

Power BI Monthly Update - September 2024

Check out the September 2024 Power BI update to learn about new features.

September Hackathon Carousel

Microsoft Fabric & AI Learning Hackathon

Learn from experts, get hands-on experience, and win awesome prizes.

Sept NL Carousel

Fabric Community Update - September 2024

Find out what's new and trending in the Fabric Community.