- Subscribe to RSS Feed
- Mark Topic as New
- Mark Topic as Read
- Float this Topic for Current User
- Bookmark
- Subscribe
- Printer Friendly Page

- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
Calculate Duration Dynamically
Hi,
Im trying to calculate the duration of an event over time in Power BI, The screenshot above is a sample of the data, what I need to do is calculate how long was spent in Status A,B,C etc. but as you can see the status can change back and forth in the data, so id need to calculate how long a duration it spent in each status but it needs to take into account the status changes , because if i was just to filter it to status A for example theres jumps in Time and vise verca so just summing that up alone wouldnt take into account that it has changed status multiple times within the day and there are time jumps which skew the results or make them look longer than it has actuually spent.
The overall aim to create a small sumary chart summing how long in total each status lasted.
In the example above it would need to be something like this:
Status Total Time Spent (minutes)
A 15
B 5
C 4
D 0
E 5
F 0
This would be straightforward to do it in excel however I have many scenarios to do it for so a dynamic solution would be preffered .
Could anyone help please
Thanks
Solved! Go to Solution.
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
Hi @Anonymous
Below is a simplified sample for your reference.
IF = IF(Table1[Status]=LOOKUPVALUE(Table1[Status],Table1[Index],Table1[Index]-1),0,1)
Group = SUMX(FILTER ( Table1, Table1[Index] <= EARLIER ( Table1[Index] ) ),Table1[IF])
DiffTime = CALCULATE ( DATEDIFF ( MIN ( Table1[DateTime] ), MAX ( Table1[DateTime] ), MINUTE ), ALLEXCEPT ( Table1, Table1[Group] ) )
Then you may get the table as below:
Table = SUMMARIZE(Table1,Table1[Status],Table1[DiffTime])
Regards,
Cherie
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
Hi @Anonymous
Below is a simplified sample for your reference.
IF = IF(Table1[Status]=LOOKUPVALUE(Table1[Status],Table1[Index],Table1[Index]-1),0,1)
Group = SUMX(FILTER ( Table1, Table1[Index] <= EARLIER ( Table1[Index] ) ),Table1[IF])
DiffTime = CALCULATE ( DATEDIFF ( MIN ( Table1[DateTime] ), MAX ( Table1[DateTime] ), MINUTE ), ALLEXCEPT ( Table1, Table1[Group] ) )
Then you may get the table as below:
Table = SUMMARIZE(Table1,Table1[Status],Table1[DiffTime])
Regards,
Cherie
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
Hi @v-cherch-msft , I have got around to trying this and it has worked more or less spot on. Thank you for your help on this.
What if I was to introduce another variable (See Screenshot below) The appliance. anf therefore wanted to do the same as before but have a total for the time spent in each status but this time for each appliance. Is this possible?
Thanks
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
Hi there, just having a hard time using DAX. How can I solve this one below? Thanks in advance.
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
Hi,
I havent got round to trying this solution yet, but it pretty much looks like exactly what i wanted.
Thank you for your help on this.
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
One approach is to create an index column, then use some conditional logic - say if the statuses are different, then it's zero, otherwise it's the difference in datetime values between this row and the previous row. There's a few threads on this if you search

Helpful resources
Join us at the Microsoft Fabric Community Conference
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Power BI Monthly Update - February 2025
Check out the February 2025 Power BI update to learn about new features.

Subject | Author | Posted | |
---|---|---|---|
08-20-2024 09:13 AM | |||
08-02-2024 10:36 AM | |||
10-17-2023 12:34 AM | |||
07-29-2024 02:57 PM | |||
06-09-2023 04:30 AM |
User | Count |
---|---|
84 | |
81 | |
52 | |
37 | |
36 |