Get certified in Microsoft Fabric—for free! For a limited time, the Microsoft Fabric Community team will be offering free DP-600 exam vouchers. Prepare now
Hi I have a table with start date/hour and end date/hour. Currently the column Workhours does NOT give the required solution, since this column includes the 48 hours of the weekend.
Goal: I want to calculate the duration in hours, but exclude the 48 hours of a weekend. When there are multiple weekends between start and end date (lets say 4 weekends) then 4 * 48 hours should be excluded.
The solution should be created in the Query editor when possible, else a calculated column. Using a dim date related table does not have my preference, for other reasons not related to this issue.
See my sample in the dropbox link data.
I also added in column H the correct answers, especially the yellow rows create difficulty.
https://www.dropbox.com/s/hmp7rdvvnxzr3eq/Duration%20without%20weekend%2048%20hours.xlsx?dl=0
Solved! Go to Solution.
Hi @FilipFireFlyBI ,
According to your description, here are my steps you can follow as a solution.
(1) My test data is the same as yours.
(2) We can create a calculated column.
WorkHour =
VAR _allmin =
GENERATESERIES(
'Table'[starttime],
'Table'[enddate],
1 / 1440
)
VAR _workmin =
FILTER(
ADDCOLUMNS(
_allmin,
"workday", WEEKDAY( [Value], 2 )
)
,
[workday] < 6
)
RETURN
COUNTROWS( _workmin ) / 60
(3) Then the result is as follows.
Please refer to the following document for more information.
Calculate time duration between 2 dates and times ... - Microsoft Power BI Community
Best Regards,
Neeko Tang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @FilipFireFlyBI ,
According to your description, here are my steps you can follow as a solution.
(1) My test data is the same as yours.
(2) We can create a calculated column.
WorkHour =
VAR _allmin =
GENERATESERIES(
'Table'[starttime],
'Table'[enddate],
1 / 1440
)
VAR _workmin =
FILTER(
ADDCOLUMNS(
_allmin,
"workday", WEEKDAY( [Value], 2 )
)
,
[workday] < 6
)
RETURN
COUNTROWS( _workmin ) / 60
(3) Then the result is as follows.
Please refer to the following document for more information.
Calculate time duration between 2 dates and times ... - Microsoft Power BI Community
Best Regards,
Neeko Tang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Check out the October 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
114 | |
96 | |
90 | |
79 | |
67 |
User | Count |
---|---|
150 | |
118 | |
111 | |
106 | |
95 |