Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
AliZreik
Frequent Visitor

Plot scheduled work shifts (with overlap and different time slot) over a 24 hours chart

Hello Community,

 

I am trying to plot the scheduled work shifts (with overlap and different time slot) for employees ove the 24 hours timespan, ideally I would like to show in each one hour slot how many employees would be available :

 

Sample Data 

 

EMP_IDShift_Start Hour

Shift_End

Hour

EMP128
EMP2512
EMP31419
EMP41923
EMP5310
EMP6810
EMP7913
EMP8316
EMP91620
EMP102224

 

Desired sample output:

 
 

Shifts.PNG

 

 

1 ACCEPTED SOLUTION

Hello @v-kelly-msft @smpa01 ,

 

I have come to a potenial solution of when the shift span from one day to another, the code goes like this :

 

#"Added Custom6" = Table.AddColumn(#"Removed Columns", "scheduled_arrived_time_h", each Time.Hour ([scheduled_arrive_time])),
#"Added Custom1" = Table.AddColumn(#"Added Custom6", "scheduled_completed_time_h", each Time.Hour ([scheduled_completed_time])),
#"Added Custom7" = Table.AddColumn(#"Added Custom1", "Hours_Scheduled", each if [scheduled_arrived_time_h] > [scheduled_completed_time_h] then List.Combine ({List.Numbers ([scheduled_arrived_time_h],24 - [scheduled_arrived_time_h]),List.Numbers (0,[scheduled_completed_time_h]+1)}) else List.Numbers ([scheduled_arrived_time_h],[scheduled_completed_time_h] - [scheduled_arrived_time_h] + 1)),
#"Expanded Hours_Scheduled" = Table.ExpandListColumn(#"Added Custom7", "Hours_Scheduled"),
#"Changed Type1" = Table.TransformColumnTypes(#"Expanded Hours_Scheduled",{{"Hours_Scheduled", Int64.Type}})

 

 

 

and the result would come like this :

 

AliZreik_0-1614508675895.png

 

Thanks, Ali

View solution in original post

15 REPLIES 15
AliZreik
Frequent Visitor

Hello @smpa01  , Below you can find a sample data with the desired output

 

Emp_Shifts.PNG

 

arrived_atcompleted_at
22/01/2021 00:0022/01/2021 01:02
22/01/2021 00:0322/01/2021 01:18
22/01/2021 00:4222/01/2021 02:15
22/01/2021 00:4422/01/2021 02:11
22/01/2021 00:5222/01/2021 05:33
22/01/2021 00:5922/01/2021 04:05
22/01/2021 01:0722/01/2021 02:00
22/01/2021 01:2222/01/2021 04:11
22/01/2021 01:2622/01/2021 10:40
22/01/2021 01:3722/01/2021 02:37
22/01/2021 02:1522/01/2021 05:22
22/01/2021 02:2722/01/2021 03:09
22/01/2021 02:5022/01/2021 04:32
22/01/2021 03:0222/01/2021 03:21
22/01/2021 03:0822/01/2021 07:00
22/01/2021 03:1522/01/2021 04:20
22/01/2021 03:4022/01/2021 04:17
22/01/2021 03:4422/01/2021 06:03
22/01/2021 03:4522/01/2021 06:07
22/01/2021 03:5822/01/2021 06:03
22/01/2021 04:0622/01/2021 04:30
22/01/2021 04:0622/01/2021 13:29
22/01/2021 04:1822/01/2021 05:49
22/01/2021 04:4322/01/2021 06:36
22/01/2021 04:5322/01/2021 06:01
22/01/2021 05:0922/01/2021 06:13
22/01/2021 05:1222/01/2021 05:43
22/01/2021 05:2122/01/2021 07:12
22/01/2021 05:2722/01/2021 06:02
22/01/2021 05:4922/01/2021 13:02
22/01/2021 05:5322/01/2021 06:30
22/01/2021 06:0222/01/2021 06:31
22/01/2021 06:0322/01/2021 13:03
22/01/2021 06:0422/01/2021 07:02
22/01/2021 06:1222/01/2021 06:29
22/01/2021 06:3022/01/2021 07:44
22/01/2021 06:3022/01/2021 14:33
22/01/2021 06:3422/01/2021 07:35
22/01/2021 06:3422/01/2021 06:35
22/01/2021 06:3522/01/2021 08:28
22/01/2021 06:4322/01/2021 09:27
22/01/2021 06:4522/01/2021 09:03
22/01/2021 06:4522/01/2021 09:59
22/01/2021 06:5022/01/2021 07:22
22/01/2021 06:5122/01/2021 07:01
22/01/2021 06:5222/01/2021 09:57
22/01/2021 06:5322/01/2021 09:02
22/01/2021 06:5322/01/2021 07:31
22/01/2021 07:0822/01/2021 08:04
22/01/2021 07:1222/01/2021 08:48
22/01/2021 07:1522/01/2021 08:30
22/01/2021 07:2422/01/2021 07:28
22/01/2021 07:2822/01/2021 08:31
22/01/2021 07:3722/01/2021 10:03
22/01/2021 07:4122/01/2021 09:00
22/01/2021 07:4222/01/2021 11:13
22/01/2021 07:4922/01/2021 10:01
22/01/2021 07:5222/01/2021 09:05
22/01/2021 08:0022/01/2021 12:32
22/01/2021 08:0122/01/2021 10:04
22/01/2021 08:0522/01/2021 09:18
22/01/2021 08:0522/01/2021 09:31
22/01/2021 08:0722/01/2021 12:20
22/01/2021 08:1222/01/2021 09:37
22/01/2021 08:1222/01/2021 10:27
22/01/2021 08:1822/01/2021 15:01
22/01/2021 08:2122/01/2021 10:01
22/01/2021 08:2422/01/2021 09:29
22/01/2021 08:3822/01/2021 09:30
22/01/2021 08:4722/01/2021 11:11
22/01/2021 08:4722/01/2021 09:21
22/01/2021 08:5322/01/2021 09:22
22/01/2021 09:0322/01/2021 09:35
22/01/2021 09:0622/01/2021 10:31
22/01/2021 09:1122/01/2021 10:08
22/01/2021 09:1322/01/2021 11:21
22/01/2021 09:2422/01/2021 11:05
22/01/2021 09:3222/01/2021 10:01
22/01/2021 09:3322/01/2021 12:08
22/01/2021 09:3922/01/2021 09:45
22/01/2021 09:5122/01/2021 13:04
22/01/2021 10:0022/01/2021 10:04
22/01/2021 10:0322/01/2021 11:16
22/01/2021 10:2622/01/2021 11:06
22/01/2021 10:3822/01/2021 12:36
22/01/2021 10:4422/01/2021 10:45
22/01/2021 10:5522/01/2021 12:07
22/01/2021 10:5722/01/2021 10:58
22/01/2021 11:0722/01/2021 12:38
22/01/2021 12:2422/01/2021 13:12
22/01/2021 12:2522/01/2021 12:35
22/01/2021 12:2722/01/2021 14:01
22/01/2021 12:2922/01/2021 15:36
22/01/2021 12:3122/01/2021 22:29
22/01/2021 12:3922/01/2021 12:40
22/01/2021 13:0122/01/2021 13:19
22/01/2021 13:0422/01/2021 14:20
22/01/2021 13:0522/01/2021 14:10
22/01/2021 13:0722/01/2021 15:05
22/01/2021 13:2422/01/2021 15:02
22/01/2021 13:2622/01/2021 15:54
22/01/2021 13:4822/01/2021 16:03
22/01/2021 13:4922/01/2021 15:27
22/01/2021 14:0122/01/2021 14:34
22/01/2021 14:0722/01/2021 14:19
22/01/2021 14:4422/01/2021 19:14
22/01/2021 14:5122/01/2021 17:05
22/01/2021 14:5922/01/2021 23:33
22/01/2021 15:0622/01/2021 16:01
22/01/2021 15:2322/01/2021 16:25
22/01/2021 15:2422/01/2021 16:13
22/01/2021 15:3022/01/2021 19:00
22/01/2021 15:3622/01/2021 18:02
22/01/2021 15:5622/01/2021 17:11
22/01/2021 15:5922/01/2021 16:35
22/01/2021 16:0022/01/2021 18:01
22/01/2021 16:2522/01/2021 19:24
22/01/2021 16:4222/01/2021 17:04
22/01/2021 16:4322/01/2021 21:30
22/01/2021 17:0422/01/2021 20:12
22/01/2021 17:1322/01/2021 20:02
22/01/2021 17:3022/01/2021 18:02
22/01/2021 17:3522/01/2021 19:39
22/01/2021 17:3722/01/2021 19:01
22/01/2021 17:5722/01/2021 20:01
22/01/2021 18:0022/01/2021 18:31
22/01/2021 18:0522/01/2021 20:01
22/01/2021 18:0622/01/2021 18:08
22/01/2021 18:1122/01/2021 20:01
22/01/2021 18:1722/01/2021 18:33
22/01/2021 18:2822/01/2021 19:01
22/01/2021 18:3322/01/2021 19:46
22/01/2021 18:5822/01/2021 19:15
22/01/2021 18:5922/01/2021 19:21
22/01/2021 18:5922/01/2021 21:00
22/01/2021 19:0022/01/2021 19:48
22/01/2021 19:1222/01/2021 19:34
22/01/2021 19:1522/01/2021 21:28
22/01/2021 19:2322/01/2021 20:30
22/01/2021 19:5622/01/2021 21:00
22/01/2021 20:0122/01/2021 20:52
22/01/2021 20:0622/01/2021 20:30
22/01/2021 20:2222/01/2021 21:53
22/01/2021 20:3022/01/2021 23:35
22/01/2021 20:3122/01/2021 20:32
22/01/2021 20:3622/01/2021 21:38
22/01/2021 20:5922/01/2021 21:33
22/01/2021 21:0022/01/2021 21:16
22/01/2021 21:0422/01/2021 23:01
22/01/2021 21:0422/01/2021 21:14
22/01/2021 21:0622/01/2021 22:02
22/01/2021 21:1022/01/2021 23:08
22/01/2021 21:2722/01/2021 23:02
22/01/2021 21:5122/01/2021 22:58
22/01/2021 21:5223/01/2021 00:03
22/01/2021 21:5323/01/2021 01:13
22/01/2021 22:2123/01/2021 00:29
22/01/2021 22:2522/01/2021 22:31
22/01/2021 22:2823/01/2021 01:32
22/01/2021 22:3022/01/2021 22:31
22/01/2021 22:5323/01/2021 00:01
22/01/2021 22:5323/01/2021 00:00
22/01/2021 23:1622/01/2021 23:24
22/01/2021 23:3323/01/2021 00:38
23/01/2021 00:0623/01/2021 02:02
23/01/2021 00:4723/01/2021 01:53
23/01/2021 00:4823/01/2021 02:17
23/01/2021 00:5323/01/2021 02:10
23/01/2021 00:5923/01/2021 02:01
23/01/2021 01:0123/01/2021 02:55
23/01/2021 01:0623/01/2021 01:38
23/01/2021 01:1823/01/2021 03:10
23/01/2021 01:3723/01/2021 02:34
23/01/2021 01:5823/01/2021 02:18
23/01/2021 02:2123/01/2021 03:01
23/01/2021 02:4423/01/2021 02:45
23/01/2021 02:5523/01/2021 04:01
23/01/2021 03:0123/01/2021 04:11
23/01/2021 03:0223/01/2021 03:29
23/01/2021 03:2923/01/2021 03:49
23/01/2021 03:3423/01/2021 04:00
23/01/2021 03:4623/01/2021 04:18
23/01/2021 04:2223/01/2021 04:23
AliZreik
Frequent Visitor

Hello @smpa01 ,

 

Thank you for the prompt reply, the solution you provided worked well up untill I found out that we have shifts that span over two days (i.e shift starts 10:00 PM and ends the next day 03:00 AM) the calculation is breaking when I have such inputs. do you have any idea how to go around this one.

 

Thanks, Ali

 

AliZreik_0-1611397833307.png

 

@AliZreik you can achieve it by this way

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUUrNLQBRhvrGhvpGBoaGCoZGVgYGQKTg6AsSN8IqEasTrWQE0Q2iDIHaDYCqjAwUsOo2MkQWj40FAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [index = _t, emp = _t, Column1 = _t, Column2 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type datetime}, {"Column2", type datetime}}),
    #"Inserted Time Subtraction" = Table.AddColumn(#"Changed Type", "Subtraction", each [Column2] - [Column1], type duration),
    #"Added Custom" = Table.AddColumn(#"Inserted Time Subtraction", "Custom", each Duration.TotalHours([Subtraction])),
    #"Inserted Year" = Table.AddColumn(#"Added Custom", "Year", each Date.Year([Column1]), Int64.Type),
    #"Inserted Month" = Table.AddColumn(#"Inserted Year", "Month", each Date.Month([Column1]), Int64.Type),
    #"Inserted Day" = Table.AddColumn(#"Inserted Month", "Day", each Date.Day([Column1]), Int64.Type),
    #"Inserted Hour" = Table.AddColumn(#"Inserted Day", "Hour", each Time.Hour([Column1]), Int64.Type),
    #"Added Custom1" = Table.AddColumn(#"Inserted Hour", "Custom.1", each List.DateTimes(#datetime([Year],[Month],[Day],[Hour],0,0),[Custom],#duration(0,1,0,0))),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom1",{"Subtraction", "Custom", "Year", "Month", "Day", "Hour"}),
    #"Expanded Custom.1" = Table.ExpandListColumn(#"Removed Columns", "Custom.1")
in
    #"Expanded Custom.1"

 

 

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs

Hello @smpa01 ,

 

Appreciated getting back to my reply, below is a snapshot of the sample data (1st snapchot), I am starting with two datetime columns, you can see below it a snaphot (2nd one) of the result after applying the code that you have sent, I am not sure why the original columns were set to mew values with 1 minute difference (almost look like all rows took values from first row in original data)

 

As for the resulted column, unlike the first time, I really didn't get how the new generated column would hep me plot the scheduled shifts (especially the ones that span 2 days) the same way as you indicated in the first reply.

 

Maybe it is obvious, but I really can't go around it.  Appreciated the support!

 

Regards, Ali

 

AliZreik_0-1611432202958.png

 

 

AliZreik_1-1611432329863.png

 

 

Hi  @AliZreik ,

 

First go to power query>create a custom column as below:

Custom=let 
st = [arrived_at],
end = [completed_at],
l = List.Generate(
    ()=>st,
    each _<=end,
    each _+#duration(0,0,1,0)
),
res=List.Select(l,(x)=>Time.Minute(x)=0 and Time.Second(x)=0)
in 
res

Then back to data view,create a calculated column as below:

Column = HOUR('Table'[Custom])

And a measure as below as below:

Measure = CALCULATE(COUNT('Table'[Column]),FILTER(ALL('Table'),'Table'[Column]=MAX('Table'[Column])&&'Table'[Column]<>BLANK()))

Finally you will see:

v-kelly-msft_0-1611742106468.png

For the related .pbix file,pls see attached.

 

Best Regards,
Kelly

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

 

 

Dear @v-kelly-msft ,

 

I have tried the Power Query Code you have provided, but the new Custom column created is mostly null values, I am not sure what I have did wrong. I can even see that in your .pbix file, that whenever the shift starts and end in the same hour, the result is null, whereas it needs to be that exact same hour (i.e. shift starts 22/01/2021 03:02:00 and ends on 22/01/2021 03:21:00) shoud return 3.

 

I am attaching snapshots of the results I got after applying the same code you have.

 

 

AliZreik_1-1611824736870.png

 

 

Thanks, Ali

Hi @AliZreik ,

 

I found that you have added a step of "Sorting Rows",try to remove the step and check whether the values are still null.

 

Best Regards,
Kelly

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

Dear @v-kelly-msft 

 

I don't think this is the problem, I have removed the Sorting and still has the same problem (check attached)

 

Thanks, Ali

 

AliZreik_0-1611912062803.png

 

Hi @AliZreik ,

 

Back to the step of "changed type“,check whether it returns blank values.

If so remove the step and insert the steps below:

v-kelly-msft_0-1612158905025.png

v-kelly-msft_1-1612158939187.png

Best Regards,
Kelly

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

 

Dear @v-kelly-msft ,

 

I have applied the Change Type using Locale as you have indicated, I am still getting null values in the newly added Custom column (check attached)

 

AliZreik_0-1612168649940.png

Thanks, Ali

Hi  @AliZreik ,

 

Then check every steps in the right queries field to see whether there is a step (before the last one) that return error or null values.

 

Best Regards,
Kelly

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

Hello @v-kelly-msft @smpa01 ,

 

I have come to a potenial solution of when the shift span from one day to another, the code goes like this :

 

#"Added Custom6" = Table.AddColumn(#"Removed Columns", "scheduled_arrived_time_h", each Time.Hour ([scheduled_arrive_time])),
#"Added Custom1" = Table.AddColumn(#"Added Custom6", "scheduled_completed_time_h", each Time.Hour ([scheduled_completed_time])),
#"Added Custom7" = Table.AddColumn(#"Added Custom1", "Hours_Scheduled", each if [scheduled_arrived_time_h] > [scheduled_completed_time_h] then List.Combine ({List.Numbers ([scheduled_arrived_time_h],24 - [scheduled_arrived_time_h]),List.Numbers (0,[scheduled_completed_time_h]+1)}) else List.Numbers ([scheduled_arrived_time_h],[scheduled_completed_time_h] - [scheduled_arrived_time_h] + 1)),
#"Expanded Hours_Scheduled" = Table.ExpandListColumn(#"Added Custom7", "Hours_Scheduled"),
#"Changed Type1" = Table.TransformColumnTypes(#"Expanded Hours_Scheduled",{{"Hours_Scheduled", Int64.Type}})

 

 

 

and the result would come like this :

 

AliZreik_0-1614508675895.png

 

Thanks, Ali

Dear @v-kelly-msft , @smpa01 

 

I have gone back one step at a time, nothing returns error or null, untill I apply the steps you have provided. I pointed out that even in your file, whene the shift starts and end on the same hour, it is returning null in your file (is that intended?)

 

I am attaching again a snapshot of the data at my hand, I can't get around why sometimes it returns null and sometimes return a value.

 

Thanks, Ali

AliZreik_0-1612452297061.png

 

Can you give me a copy-paste able sample data representative of your issue with clearly defined final output column.

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs
smpa01
Super User
Super User

@AliZreik  It can be easily done by altering the table in PQWRY

let
    Source = Web.BrowserContents("https://community.powerbi.com/t5/Desktop/Plot-scheduled-work-shifts-with-overlap-and-different-time-slot/m-p/1617671#M652662"),
    #"Extracted Table From Html" = Html.Table(Source, {{"Column1", "TABLE:nth-child(7) > * > TR > :nth-child(1)"}, {"Column2", "TABLE:nth-child(7) > * > TR > :nth-child(2)"}, {"Column3", "TABLE:nth-child(7) > * > TR > :nth-child(3)"}}, [RowSelector="TABLE:nth-child(7) > * > TR"]),
    #"Promoted Headers" = Table.PromoteHeaders(#"Extracted Table From Html", [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"EMP_ID", type text}, {"Shift_Start Hour", Int64.Type}, {"Shift_EndHour", Int64.Type}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Hours", each {[Shift_Start Hour]..[Shift_EndHour]}),
    #"Expanded Hours" = Table.ExpandListColumn(#"Added Custom", "Hours"),
    #"Changed Type1" = Table.TransformColumnTypes(#"Expanded Hours",{{"Hours", Int64.Type}})
in
    #"Changed Type1"

 and then  use Hours on X Axis.

 

I am not sure about DAX though.

Capture.PNG

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

Find out what's new and trending in the Fabric Community.