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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Arklur
Resolver II
Resolver II

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
OwenAuger
Super User
Super User

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


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

View solution in original post

4 REPLIES 4
OwenAuger
Super User
Super User

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


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn
v-shex-msft
Community Support
Community Support

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
If this post helps, please consider accept as solution to help other members find it more quickly.
Stachu
Community Champion
Community Champion

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!
Thank you for the kudos 🙂

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.

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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