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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
ningty09
Helper I
Helper I

Power BI Not Comparing Date in a Measure Properly to Date in a Data Table

Hi all,
 

 

I'm trying to compare a date measure with a date in my data table.  The date measure I have is:

 

IF(CALCULATE(SUM(YieldDataTable[RunQuantity]), FILTER(YieldDataTable,YieldDataTable[RunDate].[Date]=TODAY()))>100, TODAY(),
IF(CALCULATE(SUM(YieldDataTable[RunQuantity]), FILTER(YieldDataTable,YieldDataTable[RunDate].[Date]=TODAY()-1))>100, TODAY()-1,
IF(CALCULATE(SUM(YieldDataTable[RunQuantity]), FILTER(YieldDataTable,YieldDataTable[RunDate].[Date]=TODAY()-2))>100, TODAY()-2,
IF(CALCULATE(SUM(YieldDataTable[RunQuantity]), FILTER(YieldDataTable,YieldDataTable[RunDate].[Date]=TODAY()-3))>100, TODAY()-4,
BLANK())))

 

Which works perfectly and does exactly what I want it to do.  Below is the output it has:

1.PNG

However, when I try to use this date, it doesn't work any more (It returns a blank): 

 

Day Before Last Production Date = 
SWITCH (
    TRUE (),
    CALCULATE (
        SUM ( YieldDataTable[RunQuantity] ),
        FILTER ( YieldDataTable, YieldDataTable[RunDate].[Date] = [Last Production Date] - 1 )
    ) > 100, [Last Production Date]-1,
    CALCULATE (
        SUM ( YieldDataTable[RunQuantity] ),
        FILTER ( YieldDataTable, YieldDataTable[RunDate].[Date] = [Last Production Date] - 2 )
    ) > 100, [Last Production Date] - 2,
    CALCULATE (
        SUM ( YieldDataTable[RunQuantity] ),
        FILTER ( YieldDataTable, YieldDataTable[RunDate].[Date] = [Last Production Date] - 3 )
    ) > 100, [Last Production Date] - 3,
    CALCULATE (
        SUM ( YieldDataTable[RunQuantity] ),
        FILTER ( YieldDataTable, YieldDataTable[RunDate].[Date] = [Last Production Date] - 4 )
    ) > 100, [Last Production Date] - 4,
    BLANK ()
)
Last production date is formated as a date (M/d/yyyy), same with my data table. 
A sample of my data table date is below:
2.PNG

Any help is appreciated!

1 ACCEPTED SOLUTION
AlB
Super User
Super User

Hi @ningty09 

I haven't looked in detail but context transition might very well be having an effect in your measure. Bear in mind you are invoking it within FILTER, where there's a row context. Try:

Day Before Last Production Date = 
VAR LastProd_ = [Last Production Date]  //invoke the measure where there's no row context
SWITCH ( TRUE (), CALCULATE ( SUM ( YieldDataTable[RunQuantity] ), FILTER ( YieldDataTable, YieldDataTable[RunDate].[Date] = LastProd_ - 1 ) ) > 100, [Last Production Date]-1, CALCULATE ( SUM ( YieldDataTable[RunQuantity] ), FILTER ( YieldDataTable, YieldDataTable[RunDate].[Date] = LastProd_ - 2 ) ) > 100, [Last Production Date] - 2, CALCULATE ( SUM ( YieldDataTable[RunQuantity] ), FILTER ( YieldDataTable, YieldDataTable[RunDate].[Date] = LastProd_ - 3 ) ) > 100, [Last Production Date] - 3, CALCULATE ( SUM ( YieldDataTable[RunQuantity] ), FILTER ( YieldDataTable, YieldDataTable[RunDate].[Date] = LastProd_ - 4 ) ) > 100, [Last Production Date] - 4, BLANK () )

 

Please mark the question solved when done and consider giving kudos if posts are helpful.

Cheers  Datanaut

View solution in original post

4 REPLIES 4
AlB
Super User
Super User

Hi @ningty09 

I haven't looked in detail but context transition might very well be having an effect in your measure. Bear in mind you are invoking it within FILTER, where there's a row context. Try:

Day Before Last Production Date = 
VAR LastProd_ = [Last Production Date]  //invoke the measure where there's no row context
SWITCH ( TRUE (), CALCULATE ( SUM ( YieldDataTable[RunQuantity] ), FILTER ( YieldDataTable, YieldDataTable[RunDate].[Date] = LastProd_ - 1 ) ) > 100, [Last Production Date]-1, CALCULATE ( SUM ( YieldDataTable[RunQuantity] ), FILTER ( YieldDataTable, YieldDataTable[RunDate].[Date] = LastProd_ - 2 ) ) > 100, [Last Production Date] - 2, CALCULATE ( SUM ( YieldDataTable[RunQuantity] ), FILTER ( YieldDataTable, YieldDataTable[RunDate].[Date] = LastProd_ - 3 ) ) > 100, [Last Production Date] - 3, CALCULATE ( SUM ( YieldDataTable[RunQuantity] ), FILTER ( YieldDataTable, YieldDataTable[RunDate].[Date] = LastProd_ - 4 ) ) > 100, [Last Production Date] - 4, BLANK () )

 

Please mark the question solved when done and consider giving kudos if posts are helpful.

Cheers  Datanaut

That worked!! Thank you so much!! Can you please explain why this makes it work?

Are you familiar with context transition? If not, check this out:  https://www.sqlbi.com/articles/understanding-context-transition/

If you execute a measure inside a FILTER() the way you were doing:

FILTER ( YieldDataTable, YieldDataTable[RunDate].[Date] = [Last Production Date] - 1 )

FILTER iterates over each row of YieldDataTable and, for each one, calculates [Last Production Date]. Now, since we have row context, context transition kicks in when the measure is invoked and that means you have a filter in each of the columns. That obviously has an effect in the result of the measure. From what you showed above, you want [Last Production Date] to be calculated with no filters applied (or at least not with the ones deriving from context transition). If we invoke the measure at the beginning:

VAR LastProd_ = [Last Production Date]  //invoke the measure where there's no row context

we have no row context there, so we save the result in a VAR (immutable content) and used it subsequently as many times as necessary. Note that by using the VAR we are also more efficient since we invoke the measure only once at the beginning rather once for every row in the FILTER operations.

 

Please mark the question solved when done and consider giving kudos if posts are helpful.

Cheers  Datanaut

 

I read through the link you sent and that made sense.  Thank you!

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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