The ultimate Microsoft Fabric, Power BI, Azure AI, and SQL learning event: Join us in Stockholm, September 24-27, 2024.
Save €200 with code MSCUST on top of early bird pricing!
Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
Hi All,
I'm trying to calculate the difference in times from datetimestamp columns (Start & End) but need to exclude times between 2 times and the result is in hours and minutes.
In the example below, the period to exclude is between 10PM to 4AM and is based on Start and End slicers i.e. only calculate the times from 4AM to 10PM.
Scenario | Start | End | End - Start | Correct Time |
Fault 1 - Start >= 4AM & End < 10PM | 10/03/2022 06:25 | 10/03/2022 09:15 | 02:50 | 02:50 |
Fault 2 - Start < 4AM & End < 10PM | 11/03/2022 03:00 | 11/03/2022 10:30 | 07:30 | 06:30 |
Fault 3 - Start >= 4AM & End >= 10PM | 12/03/2022 21:10 | 12/03/2022 23:30 | 02:20 | 00:50 |
Fault 4 - Start >= 10PM & End < 4AM (before midnight) | 13/03/2022 23:00 | 13/03/2022 23:30 | 00:30 | 00:00 |
Fault 5 - Start >= 10PM & End < 4AM (end +1 day) | 14/03/2022 22:30 | 15/03/2022 02:30 | 04:00 | 00:00 |
Fault 6 - Start >=10PM & End >= 4AM | 15/03/2022 22:30 | 16/03/2022 04:30 | 06:00 | 00:30 |
Fault 7 - Start < 10PM & End >= 4AM (end +2 days) | 16/03/2022 19:00 | 18/03/2022 05:00 | 10:00 | 22:00 |
I've tried creating calculated columns to adjust the Start and End times which kind of works but not if the End is more than 1 day.
I have this Excel formula which kind of works;
=IF(End<Start,"Check Value", MAX(0,TIME(22,0,0)-MAX(MOD(Start,1),TIME(4,0,0)))+MAX(0,MIN(MOD(End,1),TIME(22,0,0))-TIME(4,0,0))+(INT(End)-INT(Start)-1)*TIME(18,0,0))
Many thanks.
Solved! Go to Solution.
Hi @M0n5ta09 ,
Yes, it is easier to work in minutes.
When I converted minutes to time, I made some mistakes. Please try this code.
Column =
VAR _a =
GENERATESERIES ( [Start], [End], TIME ( 0, 1, 0 ) )
VAR _filter =
FILTER (
_a,
TIMEVALUE ( [Value] ) > TIME ( 3, 59, 59 )
&& TIMEVALUE ( [Value] ) <= TIME ( 21, 59, 59 )
)
VAR _m =
COUNTROWS ( _filter )
RETURN
ROUNDDOWN ( _m / 60, 0 ) & ":"
& MOD ( _m, 60 )
Best Regards
Community Support Team _ chenwu zhu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @M0n5ta09 ,
Please try this expression to do it:
Column =
VAR _a =
GENERATESERIES ( [Start], [End], TIME ( 0, 1, 0 ) )
VAR _filter =
FILTER (
_a,
TIMEVALUE ( [Value] ) > TIME ( 3, 59, 59 )
&& TIMEVALUE ( [Value] ) <= TIME ( 21, 59, 59 )
)
RETURN
TIME ( 0, COUNTROWS ( _filter ), 0 )
Result:
Pbix in the end you can refer.
Best Regards
Community Support Team _ chenwu zhu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Thank you. Apologies for the delay reply.
This works for a majority but not with these Start and End. I'm guessing because the hours are over 24;
Fault | Start | End | Column |
1 | 30/04/2022 10:58:04 | 01/05/2022 21:20:00 | 4:22:00 |
2 | 01/05/2022 13:00:00 | 03/05/2022 19:30:00 | 18:30:00 |
Fault 1:
10:58 to 22:00 = 11:02 or 662 minutes
04:00 to 21:20 = 17:20 or 1040 minutes
Result should be 11:02 + 17:20 = 18:22 or 1102 minutes
Fault 2:
01/05/2022 13:00 to 22:00 = 9:00 or 540 minutes
02/05/2022 04:00 to 22:00 = 18:00 or 1080 minutes
03/05/2022 04:00 to 19:30 = 15:30 or 930 minutes
Result should be 9:00 + 18:00 + 15:30 = 42:30:00 or 2550 minutes
Is it easier to work in minutes and convert to time afterwards?
Hi @M0n5ta09 ,
Yes, it is easier to work in minutes.
When I converted minutes to time, I made some mistakes. Please try this code.
Column =
VAR _a =
GENERATESERIES ( [Start], [End], TIME ( 0, 1, 0 ) )
VAR _filter =
FILTER (
_a,
TIMEVALUE ( [Value] ) > TIME ( 3, 59, 59 )
&& TIMEVALUE ( [Value] ) <= TIME ( 21, 59, 59 )
)
VAR _m =
COUNTROWS ( _filter )
RETURN
ROUNDDOWN ( _m / 60, 0 ) & ":"
& MOD ( _m, 60 )
Best Regards
Community Support Team _ chenwu zhu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.
Check out the August 2024 Power BI update to learn about new features.
User | Count |
---|---|
111 | |
80 | |
71 | |
51 | |
50 |
User | Count |
---|---|
129 | |
123 | |
78 | |
64 | |
60 |