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

Enhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.

Reply
LuciferMstar
Helper I
Helper I

Conditional date difference

Hello,

 

I'm struggling with some comparisons and date difference when I have this kind of data in which some cells are blanks.

What do I need to do here is to compare each value in the specified columns, for each ID, and depending on the condition to calculate the DateDiff.

 

The logic would be like this: If [Status 2] > [Status 1] and [Status 2] < [Status 3] then [Status 3] - [Status 2].

 

IDStatus 1Status 2Status 3
118/01/2022  
115/02/202202/02/202206/04/2022
1 23/03/2022 
2 25/04/202329/04/2023
215/04/202327/04/202310/04/2023

 

The output would be like this:

IDDays 
178
114
24
22

 

Thank you!

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @LuciferMstar 

You can try the following column

Days =
VAR a =
    FILTER ( 'Table', [ID] = EARLIER ( 'Table'[ID] ) )
VAR b =
    ADDCOLUMNS (
        SUMMARIZE ( FILTER ( a, [Status 1] <> BLANK () ), [Status 1] ),
        "Status 2", MINX ( FILTER ( a, [Status 2] > EARLIER ( 'Table'[Status 1] ) ), [Status 2] )
    )
VAR c =
    ADDCOLUMNS (
        b,
        "Status 3", MINX ( FILTER ( a, [Status 3] > EARLIER ( [Status 2] ) ), [Status 3] )
    )
VAR d =
    ADDCOLUMNS ( c, "Dateiff", DATEDIFF ( [Status 2], [Status 3], DAY ) )
RETURN
    MAXX ( FILTER ( d, [Status 2] = EARLIER ( 'Table'[Status 2] ) ), [Dateiff] )

vxinruzhumsft_0-1684977099777.png

and the result you have offered the dateiff of 

25/10/2022 18/11/2022  

should be 24

 

Best Regards!

Yolo Zhu

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

4 REPLIES 4
Anonymous
Not applicable

Hi @LuciferMstar 

You can refer to the following calculated column

Days =
VAR _loopup1 =
    FILTER ( 'Table', [ID] = EARLIER ( 'Table'[ID] ) )
VAR _status1 =
    MAXX ( _loopup1, [Status 1] )
VAR _status2 =
    MAXX ( _loopup1, [Status 2] )
VAR _status3 =
    MAXX ( _loopup1, [Status 3] )
RETURN
    IF (
        _status1 < _status2
            && _status2 < _status3,
        IF ( [Status 2] <> BLANK (), DATEDIFF ( [Status 2], _status3, DAY ) )
    )

vxinruzhumsft_0-1684894279990.png

 

Best Regards!

Yolo Zhu

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Hi @Anonymous ,

 

Thank you, in some cases it works, but in other cases it doesn't because of MAXX.

 

In the following example it needs to ignore the first row because the first Status 2 date falls below of the first Status 1 date, and should perform the first DATEDIFF only on the first Status 3 date that comes only after the second Status 2 date. 


Now, the thing is that I might have another set of Status 1, Status 2 and Status 3 and that would mean a second DATEDIFF. 

IDStatus NameStatus Created DateStatus 1Status 2Status 3Days
5Status 203/01/2022 03/01/2022 346
5Status 110/01/202210/01/2022   
5Status 318/02/2022  18/02/2022 
5Status 324/02/2022  24/02/2022 
5Status 225/02/2022 25/02/2022 143
5Status 318/07/2022  18/07/2022 
5Status 315/08/2022  15/08/2022 
5Status 318/08/2022  18/08/2022 
5Status 320/09/2022  20/09/2022 
5Status 110/10/202210/10/2022   
5Status 225/10/2022 25/10/2022 51
5Status 318/11/2022  18/11/2022 
5Status 315/12/2022  15/12/2022 
Anonymous
Not applicable

Hi @LuciferMstar 

You can try the following column

Days =
VAR a =
    FILTER ( 'Table', [ID] = EARLIER ( 'Table'[ID] ) )
VAR b =
    ADDCOLUMNS (
        SUMMARIZE ( FILTER ( a, [Status 1] <> BLANK () ), [Status 1] ),
        "Status 2", MINX ( FILTER ( a, [Status 2] > EARLIER ( 'Table'[Status 1] ) ), [Status 2] )
    )
VAR c =
    ADDCOLUMNS (
        b,
        "Status 3", MINX ( FILTER ( a, [Status 3] > EARLIER ( [Status 2] ) ), [Status 3] )
    )
VAR d =
    ADDCOLUMNS ( c, "Dateiff", DATEDIFF ( [Status 2], [Status 3], DAY ) )
RETURN
    MAXX ( FILTER ( d, [Status 2] = EARLIER ( 'Table'[Status 2] ) ), [Dateiff] )

vxinruzhumsft_0-1684977099777.png

and the result you have offered the dateiff of 

25/10/2022 18/11/2022  

should be 24

 

Best Regards!

Yolo Zhu

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Hi @Anonymous ,

 

Many thanks! It works!

Helpful resources

Announcements
August Power BI Update Carousel

Power BI Monthly Update - August 2025

Check out the August 2025 Power BI update to learn about new features.

August 2025 community update carousel

Fabric Community Update - August 2025

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

Top Solution Authors