Reply
Highlighted
New Member
Posts: 1
Registered: ‎11-30-2018
Accepted Solution

Calculate Duration Dynamically

AVLS data output for Forum.PNG

 

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

 

 


Accepted Solutions
Community Support Team
Posts: 1,380
Registered: ‎07-25-2018

Re: Calculate Duration Dynamically

Hi @Sher

 

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])

1.png

 

Regards,

Cherie

Community Support Team _ Cherie Chen
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


All Replies
Super User
Posts: 442
Registered: ‎07-12-2017

Re: Calculate Duration Dynamically

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

Community Support Team
Posts: 1,380
Registered: ‎07-25-2018

Re: Calculate Duration Dynamically

Hi @Sher

 

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])

1.png

 

Regards,

Cherie

Community Support Team _ Cherie Chen
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.