cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Arklur Regular Visitor
Regular Visitor

CALCULATE behaviour when using in a new column

I have a very simple source data to demonstrate my problem I run into:

 

 

I can easily calculate the total "Amount" of the "Child" table for the "Parent" table using a simply DAX:

 

SumTotalValue = CALCULATE(SUM(Child[Amount]))

 

 

But if I try to add a new filter for CALCULATE, looks like it drops the filter context and only use the one I provided:

 

SumBefore2017 = CALCULATE(SUM(Child[Amount]); FILTER(Child;Child[Year] < 2017))

 

 

 

+1: I realized I (likely) should use these DAX expressions for such usage (I think it provides a better performance, though haven't checked it yet):

SumTotalValue = SUMX(RELATEDTABLE(Child);Child[Amount])

SumBefore2017 = SUMX(FILTER(RELATEDTABLE(Child);Child[Year] < 2017);Child[Amount])

 

,but still curious about this behaviour.

1 ACCEPTED SOLUTION

Accepted Solutions
OwenAuger Super Contributor
Super Contributor

Re: CALCULATE behaviour when using in a new column

Hi @Arklur

 

Probably the simplest way to write your 2nd calculated column is:

SumBefore2017 =
CALCULATE ( SUM ( Child[Amount] ); Child[Year] < 2017 )

The reason your original version lost the filter context obtained from the row of Parent (through context transition) was that the FILTER(Child...) argument over-rode it.

 

  1. FILTER(Child...) is evaluated in the original context (outside CALCULATE) where Child is unfiltered.
  2. On top of that, Child when used as a filter argument within CALCULATE is treated as the expanded table which includes all columns of Parent, so including it as a filter argument over-rides the filter context obtained from the "current row" of Parent.
  3. The suggested calculated column above adds a filter only on Child[Year], so the other filters on columns of the Parent table are retained.

 

Here are a couple of good articles that cover these points in more depth:

https://www.sqlbi.com/articles/context-transition-and-filters-in-calculate/

https://mdxdax.blogspot.com/2011/03/logic-behind-magic-of-dax-cross-table.html

 

Regards,

Owen



Did I answer your question? Mark my post as a solution!

Proud to be a Datanaut!




4 REPLIES 4
Highlighted
Stachu Super Contributor
Super Contributor

Re: CALCULATE behaviour when using in a new column

I suggest creating measures instead of columns - with the same syntax, they will propagate filter context properly
as a measure SumBefore2017 can be just

SumBefore2017 = CALCULATE(SUM(Child[Amount]); Child[Year] < 2017)
Did I answer your question? Mark my post as a solution!

Proud to be a Datanaut!

Arklur Regular Visitor
Regular Visitor

Re: CALCULATE behaviour when using in a new column

Thanks for the idea, though it doesn't really answer my question / I've already knew the downsides of creating calculated columns instead of creating them as a measure.

Community Support Team
Community Support Team

Re: CALCULATE behaviour when using in a new column

Hi @Arklur,

 

After checking your formula, I found you forget to add condition to check current parentID, you can try to use below measure(calculated column) to achieve your requirement.

SumBefore2017 =
CALCULATE (
    SUM ( Child[Amount] );
    FILTER (
        ALL ( Child );
        Child[ParentId] = EARLIER ( Parent[ParentId] )
            && Child[Year] < 2017
    )
)

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin Sheng
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.



For learning resources/Release notes, please visit: | |
OwenAuger Super Contributor
Super Contributor

Re: CALCULATE behaviour when using in a new column

Hi @Arklur

 

Probably the simplest way to write your 2nd calculated column is:

SumBefore2017 =
CALCULATE ( SUM ( Child[Amount] ); Child[Year] < 2017 )

The reason your original version lost the filter context obtained from the row of Parent (through context transition) was that the FILTER(Child...) argument over-rode it.

 

  1. FILTER(Child...) is evaluated in the original context (outside CALCULATE) where Child is unfiltered.
  2. On top of that, Child when used as a filter argument within CALCULATE is treated as the expanded table which includes all columns of Parent, so including it as a filter argument over-rides the filter context obtained from the "current row" of Parent.
  3. The suggested calculated column above adds a filter only on Child[Year], so the other filters on columns of the Parent table are retained.

 

Here are a couple of good articles that cover these points in more depth:

https://www.sqlbi.com/articles/context-transition-and-filters-in-calculate/

https://mdxdax.blogspot.com/2011/03/logic-behind-magic-of-dax-cross-table.html

 

Regards,

Owen



Did I answer your question? Mark my post as a solution!

Proud to be a Datanaut!




Helpful resources

Announcements
Can You Solve These Challenge

Challenge: Can You Solve These?

Find out how to participate in the first Power BI 'Can You Solve These?' challenge.

Community News & Announcements

Community News & Announcements

Get your latest community news and announcements.

Virtual Launch Event

Microsoft Business Applications October Virtual Launch Event

Join us for an in-depth look at the new innovations across Dynamics 365 and the Microsoft Power Platform.

Community Kudopalooza

Win Power BI Swag with Community Kudopalooza!

Each week, complete activities and be qualified in the drawing for cool Power BI Swag.

Users Online
Currently online: 205 members 2,291 guests
Please welcome our newest community members: