cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
Anonymous
Not applicable

Calculate duration of states

Hello All,

 

I am trying to calculate the duration between two on and off states.

Sample data :- 

DateTimeStatus
7/7/20189:59:53 AMON
7/7/201810:50:53 AMOFF
7/8/20189:26:52 AMON
7/8/201810:20:52 AMOFF
7/9/20183:59:51 AMON
7/9/20184:14:51 AMOFF
7/9/20185:50:50 AMON
7/9/20187:35:50 AMOFF
7/9/20188:26:50 AMON
7/9/20188:35:50 AMOFF

 

Now i would lik to calcualte the duration from states between ON to OFF but not OFF to ON.

i.e nothing but, i am trying to calculate only the total ON duration.

 

For Ex:- 

In above data for 7/9/2018

7/9/20183:59:51 AMON0
7/9/20184:14:51 AMOFF0.15
7/9/20185:50:50 AMON0
7/9/20187:35:50 AMOFF1.35
7/9/20188:26:50 AMON0
7/9/20188:35:50 AMOFF0.9

 

 

How can i get this done in dax.

 

Please suggest me.

 

Thanks,

Mohan V

1 ACCEPTED SOLUTION

Accepted Solutions
Highlighted
Microsoft
Microsoft

Re: Calculate duration of states

Hi @Anonymous,

 

Please firstly add an index column in Query Editor mode. Then, create a calculated column with below DAX formula:

Duration =
IF (
    TB1[Status] = "OFF",
    DATEDIFF (
        CALCULATE (
            MAX ( TB1[Time] ),
            FILTER (
                ALLEXCEPT ( TB1, TB1[Date] ),
                TB1[Index]
                    = EARLIER ( TB1[Index] ) - 1
                    && TB1[Status] = "ON"
            )
        ),
        TB1[Time],
        MINUTE
    ),
    0
)

Regards,

Yuliana Gu

Community Support Team _ Yuliana Gu
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
Highlighted
Solution Sage
Solution Sage

Re: Calculate duration of states

Dont have time right now to think this through but to get you ponted in the right direction, you need to use a calcualted column with EARLIER in the filter crtieria.

Highlighted
Microsoft
Microsoft

Re: Calculate duration of states

Hi @Anonymous,

 

Please firstly add an index column in Query Editor mode. Then, create a calculated column with below DAX formula:

Duration =
IF (
    TB1[Status] = "OFF",
    DATEDIFF (
        CALCULATE (
            MAX ( TB1[Time] ),
            FILTER (
                ALLEXCEPT ( TB1, TB1[Date] ),
                TB1[Index]
                    = EARLIER ( TB1[Index] ) - 1
                    && TB1[Status] = "ON"
            )
        ),
        TB1[Time],
        MINUTE
    ),
    0
)

Regards,

Yuliana Gu

Community Support Team _ Yuliana Gu
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

Highlighted
Frequent Visitor

Re: Calculate duration of states

Hello!

I think my solution could be similar to this one, but I need to incorporate the date in axis.. Could you please take a look? Real thanks! 

https://community.powerbi.com/t5/Desktop/Distinct-Count-of-Last-Status-over-time/m-p/647252 

 

(You can copy paste link, site is working weird today)

Helpful resources

Announcements
Community Blog

Community Blog

Visit our Community Blog for articles, guides, and information created by fellow community members.

Using the Community

Using the Community

Need help with the Power BI Community? Our 'Using the Community' support articles are a great place to start.

Community Summit North America

Community Summit North America

Innovate, Collaborate, Grow. The top training and networking event across the globe for Microsoft Business Applications

Power Platform 2020 release wave 2 plan

Power Platform 2020 release wave 2 plan

Features releasing from October 2020 through March 2021

Top Solution Authors
Top Kudoed Authors