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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
Anonymous
Not applicable

Calculate duration between dates in different rows and filtered on a value

I have searched and searched and can't seem to find the same scenario. I am trying to calulate the duration an item takes from one step to the next. My table looks like below.

 

The "INC_ENTRY_ID" will appear multiple times if that specific record changes. 

 

chrismcd01_0-1667361736919.png

 

So, in that data woudl be something like below:

 

chrismcd01_1-1667361972909.png

 

What I need to do is calculate the duration from the earliest date to the next date and then the next date, and so on for each unique "INC_ENTRY_ID" - the other columns will not be duplicated (they are either index or a different id series)

 

Help 🙂

 

I should add that I will really be drilling into this from a summary view if a user wants to see more details. So, in a different report they would be clicking on a value for the first column. So, I don't need to view everything at once... it would be a filtered view of a value from the first column. 

 

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

Hi @Anonymous ,

 

Please try following DAX:

Column = 
var _date = MINX(FILTER('Table','Table'[INC_ENTRY_ID] = EARLIER('Table'[INC_ENTRY_ID]) && 'Table'[AUDIT_DATE] > EARLIER('Table'[AUDIT_DATE])),'Table'[AUDIT_DATE])
return
DATEDIFF([AUDIT_DATE],_date,MINUTE)

 

The result you want:

vyadongfmsft_0-1668068799805.png

 

Best regards,

Yadong Fang

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

3 REPLIES 3
v-yadongf-msft
Community Support
Community Support

Hi @Anonymous ,

 

Please try following DAX:

Column = 
var _date = MINX(FILTER('Table','Table'[INC_ENTRY_ID] = EARLIER('Table'[INC_ENTRY_ID]) && 'Table'[AUDIT_DATE] > EARLIER('Table'[AUDIT_DATE])),'Table'[AUDIT_DATE])
return
DATEDIFF([AUDIT_DATE],_date,MINUTE)

 

The result you want:

vyadongfmsft_0-1668068799805.png

 

Best regards,

Yadong Fang

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

amitchandak
Super User
Super User

@Anonymous , Based on what I got, a new column

 

New column =

var _date  = maxx(filter(Table, [INC_ENTRY_ID] = earlier([INC_ENTRY_ID]) && [Audit_date] < earlier([Audit_date]) ) , [Audit_date])

return

datediff(_date,[Audit_date], second)

 

 

Or if you need time

return

[Audit_date] - _date

 

Power BI DAX- Earlier, I should have known Earlier: https://youtu.be/CVW6YwvHHi8

Share with Power BI Enthusiasts: Full Power BI Video (20 Hours) YouTube
Microsoft Fabric Series 60+ Videos YouTube
Microsoft Fabric Hindi End to End YouTube
Anonymous
Not applicable

@amitchandak - Thank you again. I did notice one problem that I have not been able to figure out. The formula does accurately calculate the duration; however, the duration does not appear on the correct row. 

 

So - duration is calculating correctly but it should show up on the previous row. For example, in the screenshot below, the first row started with the group "General Triage" on 10/25/2002 at 7:20 AM. It was with that group for 1980 minutes before it went to the "Virtual Desktop" group who then had it for 881 minutes and so on. Any idea how to fix that?

 

chrismcd01_0-1667441612654.png

 

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.