cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
RvdC
Frequent Visitor

Calculating with DAX the total Interruption Time with overlapping intervals

I have a challenge with this case:

 

There is a technical installation which produces products on order. Only one order at the time. Each order has a unique ID. It starts with the starts order activity and ends with the end order activity. Within some orders there are disruptions who will delay the throughput time. A delay has a start interruption and an end interruption activity. Each start-end interruption (combination) has also a unique Interruption ID. Normally it would be easy to calculate the gross, net and total throughput time and total interruption time per order. But some interruptions have one or more overlaps. How can I calculate with DAX the total interruption time defined as the exact time the production order is delayed? Even if there are one or more (partly) overlaps within a certain overlap.

Hereby an example of a table with 4 variations:

 

Screenshot order table.PNG

Hope there is a solution for the total delay time calculation.

Thanks in advance.

1 ACCEPTED SOLUTION

@RvdC ,

 

Hey thanks for pointing that out.

 

i had missed checking a gap in between interupption time.

 

Hope this works.

 

 

@RvdC ,

 

Thanks, There is a gap of 10 mins in between. I did not notice that.

 

Hope this works.

 

 

Calculated Columns

 

End of Previous InteruptionID = IF (Table4[Activity] = "Start Interruption", CALCULATE(MAX(Table4[Date/Time End]),FILTER(ALLEXCEPT(Table4,Table4[Order_ID]), Table4[Interuption ID]<EARLIER(Table4[Interuption ID]) && Table4[Activity] = "Start Interruption")))

 

 

Gaps in Between = IF ( Table4[End of Previous InteruptionID] < Table4[Date/Time], DATEDIFF(Table4[End of Previous InteruptionID], Table4[Date/Time],MINUTE))

 

 

 

Measure

Interuption Time (Orders) =

var _addgaps = CALCULATE(SUM(Table4[Gaps in Between]), ALLEXCEPT(Table4, Table4[Order_ID]))
var _StartTime = CALCULATE(MIN(Table4[Date/Time]),Filter(ALLEXCEPT(Table4,Table4[Order_ID]), Table4[Activity] = "Start Interruption"))
var _EndTime = CALCULATE(MAX(Table4[Date/Time End]),Filter(ALLEXCEPT(Table4,Table4[Order_ID]), Table4[Activity] = "Start Interruption"))

return
 
DATEDIFF(_StartTime,_EndTime,MINUTE) - _addgaps
 
 
1.jpg2.JPG
 
 
Regards,
Harsh Nathani
Did I answer your question? Mark my post as a solution! Appreciate with a Kudos!!

View solution in original post

4 REPLIES 4
harshnathani
Super User III
Super User III

Hi @RvdC ,

 

You can try this solution.

 

Let me know if this works for you.

1.jpg2.JPG3.JPG

 

Create Calculated Column

 

Date/Time End = IF (Table4[Interuption ID] = BLANK() || Table4[Activity] = "End Interruption", BLANK(),
CALCULATE(
MAX(Table4[Date/Time]),
FILTER(Table4 , Table4[Interuption ID] = EARLIER(Table4[Interuption ID]))))
 
 
Time Difference (Interuption ID) = DATEDIFF(Table4[Date/Time],Table4[Date/Time End], MINUTE)
 
 
Create Measure for 
 
Interuption Time (Orders) =

var _StartTime = CALCULATE(MIN(Table4[Date/Time]),Filter(ALLEXCEPT(Table4,Table4[Order_ID]), Table4[Activity] = "Start Interruption"))
var _EndTime = CALCULATE(MAX(Table4[Date/Time End]),Filter(ALLEXCEPT(Table4,Table4[Order_ID]), Table4[Activity] = "Start Interruption"))

return
DATEDIFF(_StartTime,_EndTime,MINUTE)

 

 

Regards,

Harsh Nathani

Did I answer your question? Mark my post as a solution! Appreciate with a Kudos!!

 

Hi Harsh,

 

Thanks for your solution! I have tested it, got the same results. It works almost perfect. The net dealy time for Case D is 75 minutes in stead of 85 minutes. The delay time is the 5 minutes from start I4 tot end I4 + the start from I5 untill the end of I7 (70 minutes). Makes a total of 75 minutes. The script adds somewhere 10 minutes to it. Do you have a solution for that?

Maybe I am overlooking something.

 

Thanks already for your support.

Regards,

Rob van de Coevering

@RvdC ,

 

Hey thanks for pointing that out.

 

i had missed checking a gap in between interupption time.

 

Hope this works.

 

 

@RvdC ,

 

Thanks, There is a gap of 10 mins in between. I did not notice that.

 

Hope this works.

 

 

Calculated Columns

 

End of Previous InteruptionID = IF (Table4[Activity] = "Start Interruption", CALCULATE(MAX(Table4[Date/Time End]),FILTER(ALLEXCEPT(Table4,Table4[Order_ID]), Table4[Interuption ID]<EARLIER(Table4[Interuption ID]) && Table4[Activity] = "Start Interruption")))

 

 

Gaps in Between = IF ( Table4[End of Previous InteruptionID] < Table4[Date/Time], DATEDIFF(Table4[End of Previous InteruptionID], Table4[Date/Time],MINUTE))

 

 

 

Measure

Interuption Time (Orders) =

var _addgaps = CALCULATE(SUM(Table4[Gaps in Between]), ALLEXCEPT(Table4, Table4[Order_ID]))
var _StartTime = CALCULATE(MIN(Table4[Date/Time]),Filter(ALLEXCEPT(Table4,Table4[Order_ID]), Table4[Activity] = "Start Interruption"))
var _EndTime = CALCULATE(MAX(Table4[Date/Time End]),Filter(ALLEXCEPT(Table4,Table4[Order_ID]), Table4[Activity] = "Start Interruption"))

return
 
DATEDIFF(_StartTime,_EndTime,MINUTE) - _addgaps
 
 
1.jpg2.JPG
 
 
Regards,
Harsh Nathani
Did I answer your question? Mark my post as a solution! Appreciate with a Kudos!!

View solution in original post

Thanks a lot for your help! All works fine for me.

Best,

Rob

Helpful resources

Announcements
PBI User Groups

Welcome to the User Group Public Preview

Check out new user group experience and if you are a leader please create your group!

MBAS on Demand

Microsoft Business Applications Summit sessions

On-demand access to all the great content presented by the product teams and community members! #MSBizAppsSummit #CommunityRocks

Get Ready for Power BI Dev Camp

Power BI Dev Camp - June 24th

Mark your calendars and join us for our next Power BI Dev Camp!

Top Solution Authors
Top Kudoed Authors