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
madalin
Regular Visitor

DAX formula for calculating diff date of consecutive rows

Hi, 

 

I'm new to DAX and I need your help.

 

I have the following table:

 

device_idtimedisplay_timeCalculate
AA9/10/2020 01:029/10/2020 01:0200:01:00
AA9/10/2020 13:059/10/2020 01:0500:03:34
AA9/10/2020 01:069/10/2020 01:0600:00:41
AA9/10/2020 13:099/10/2020 13:0912:03:34
BB9/11/2020 00:289/11/2020 00:28 00:01:00
BB9/11/2020 12:309/11/2020 12:3012:02:16
BB9/11/2020 00:329/11/2020 12:3200:02:37
BB9/11/2020 12:359/11/2020 12:3500:02:15
CC9/10/2020 09:599/10/2020 09:59 00:01:00
CC9/10/2020 22:019/10/2020 22:0112:01:30
CC9/10/2020 10:039/10/2020 22:0300:02:14
CC9/10/2020 22:059/10/2020 22:0500:02:07

 

madalin_0-1600383491691.png

 

I want to calculate de difference in seconds between two consecutive display times for a device( like in the Calculate column) and if it's possible for the first display_time for a device to insert a value e.g. 60 seconds.

 

I've tried adding first an index column and after that using the DATEDIFF formula but I can't properly sort the table and get right the consecutive values for display_time when I used an Index column.

 

 

Kind regards,

Madalin

 

 

 

1 ACCEPTED SOLUTION
v-alq-msft
Community Support
Community Support

Hi, @madalin 

 

Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.

Table:

g1.png

 

You may create a measure as below.

Seconds = 
var tab = 
ADDCOLUMNS(
    ALL('Table'),
    "Result",
    var _lastdatetime =
    CALCULATE(
        MAX('Table'[Display_Time]),
        FILTER(
            ALL('Table'),
            'Table'[Device_ID]=EARLIER('Table'[Device_ID])&&
            'Table'[Display_Time]<EARLIER('Table'[Display_Time])
        )
    )
    return
    IF(
        ISBLANK(_lastdatetime),
        60,
        DATEDIFF(_lastdatetime,[Display_Time],SECOND)
    )
)
return
SUMX(
    ADDCOLUMNS(
        'Table',
        "Re",
        SUMX(
            FILTER(
                tab,
                [Device_ID]=EARLIER('Table'[Device_ID])&&
                [Display_Time]=EARLIER('Table'[Display_Time])
            ),
            [Result]
        )
    ),
    [Re]
)

 

Result:

g2.png

 

Best Regards

Allan

 

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

2 REPLIES 2
v-alq-msft
Community Support
Community Support

Hi, @madalin 

 

Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.

Table:

g1.png

 

You may create a measure as below.

Seconds = 
var tab = 
ADDCOLUMNS(
    ALL('Table'),
    "Result",
    var _lastdatetime =
    CALCULATE(
        MAX('Table'[Display_Time]),
        FILTER(
            ALL('Table'),
            'Table'[Device_ID]=EARLIER('Table'[Device_ID])&&
            'Table'[Display_Time]<EARLIER('Table'[Display_Time])
        )
    )
    return
    IF(
        ISBLANK(_lastdatetime),
        60,
        DATEDIFF(_lastdatetime,[Display_Time],SECOND)
    )
)
return
SUMX(
    ADDCOLUMNS(
        'Table',
        "Re",
        SUMX(
            FILTER(
                tab,
                [Device_ID]=EARLIER('Table'[Device_ID])&&
                [Display_Time]=EARLIER('Table'[Display_Time])
            ),
            [Result]
        )
    ),
    [Re]
)

 

Result:

g2.png

 

Best Regards

Allan

 

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

 

AlB
Super User
Super User

Hi @madalin 

Try this for your new column:

New Column = 
VAR current_ = Table1[display_time]
VAR previous_ =
    CALCULATE (
        MAX ( Table1[display_time] ),
        Table1[display_time] < EARLIER ( Table1[display_time] ),
        ALLEXCEPT ( Table1, Table1[device_id] )
    )
RETURN
    IF ( ISBLANK ( previous_ ), 1 / 24, previous_ - current_ )

 This will give you the result in days (decimal number). You can change the type to time if you want to show it in the format you used in your example but take into account that that only will show up to 23:59:59

 

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

Contact me privately for support with any larger-scale BI needs, tutoring, etc.

Cheers 

 

SU18_powerbi_badge

 

 

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.

Top Solution Authors
Top Kudoed Authors