I have a table WorkPerDay which tells me how many hours each person, should work per day.
id | personId | date | hours
--------------------------
0 | 0 | 01.01.2022 | 8
1 | 0 | 02.01.2022 | 8
2 | 0 | 03.01.2022 | 8
3 | 1 | 01.01.2022 | 8
4 | 1 | 02.01.2022 | 8
5 | 1 | 03.01.2022 | 8
I also have a table Tasks which describes tasks that need doing, when they need doing, and how long they take to do
id | startDate | dueDate | totalHours
---------------------------------------
0 | 01.01.2022 | 08.01.2022 | 14
1 | 07.01.2022 | 08.01.2022 | 10
My goal is to create a chart where I can compare the total available hourse (based on the workPerDay table) and the hours of work required according to the Tasktable. The hour of work per day per task should be calculated by dividing the totalHours evenly between the startDate and dueDate. So for id 0 I required 2 hours of work on each of 01,02,03,04,05,06,07.01.2022.
My idea would be to blow up the task table into individual dates
id | taskId | Date | hours
---------------------------------------
0 | 0 | 01.01.2022 | 2
1 | 0 | 02.01.2022 | 2
2 | 0 | 03.01.2022 | 2
3 | 0 | 04.01.2022 | 2
4 | 0 | 05.01.2022 | 2
5 | 0 | 06.01.2022 | 2
6 | 0 | 07.01.2022 | 2
7 | 1 | 07.01.2022 | 10
Which I could then relate to my WorkPerDay table by date.
The problem is I don't know if this is right idea, and also not how to start doing this. Any help would be appreciated!
Solved! Go to Solution.
Hi, @claudeHasler
Yes. It's an executable idea.
About how to blow up the task table into individual dates, you can try following steps in PowerQuery.
1.add custom columns to calculate the interval days and the working hours required per day
=Duration.TotalDays([dueDate]-[startDate])
=[totalHours]/[Custom]
2.add another list to contain all dates in this period (List.Dates )
=List.Dates([startDate],[Custom],#duration(1, 0, 0, 0))
3.Expend the list -> remove the column you do not want -> rename the new column->add index column
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlDSUTIyMDLSNTAEImSOBZBjaKIUqxOthCJujqHIQCk2FgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, startDate = _t, dueDate = _t, totalHours = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"startDate", type date}, {"dueDate", type date}, {"totalHours", Int64.Type}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each Duration.TotalDays([dueDate]-[startDate])),
#"Added Custom1" = Table.AddColumn(#"Added Custom", "Hours", each [totalHours]/[Custom]),
#"Added Custom2" = Table.AddColumn(#"Added Custom1", "Custom.1", each List.Dates([startDate],[Custom],#duration(1, 0, 0, 0))),
#"Expanded Custom.1" = Table.ExpandListColumn(#"Added Custom2", "Custom.1"),
#"Removed Columns" = Table.RemoveColumns(#"Expanded Custom.1",{"startDate", "dueDate", "totalHours", "Custom"}),
#"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"Custom.1", "Date"}, {"ID", "TaskID"}}),
#"Added Index" = Table.AddIndexColumn(#"Renamed Columns", "Index", 0, 1, Int64.Type),
#"Reordered Columns" = Table.ReorderColumns(#"Added Index",{"Index", "TaskID", "Date", "Hours"})
in
#"Reordered Columns"
Please check my sample file for more details.
Best Regards,
Community Support Team _ Eason
Hi, @claudeHasler
Yes. It's an executable idea.
About how to blow up the task table into individual dates, you can try following steps in PowerQuery.
1.add custom columns to calculate the interval days and the working hours required per day
=Duration.TotalDays([dueDate]-[startDate])
=[totalHours]/[Custom]
2.add another list to contain all dates in this period (List.Dates )
=List.Dates([startDate],[Custom],#duration(1, 0, 0, 0))
3.Expend the list -> remove the column you do not want -> rename the new column->add index column
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlDSUTIyMDLSNTAEImSOBZBjaKIUqxOthCJujqHIQCk2FgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, startDate = _t, dueDate = _t, totalHours = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"startDate", type date}, {"dueDate", type date}, {"totalHours", Int64.Type}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each Duration.TotalDays([dueDate]-[startDate])),
#"Added Custom1" = Table.AddColumn(#"Added Custom", "Hours", each [totalHours]/[Custom]),
#"Added Custom2" = Table.AddColumn(#"Added Custom1", "Custom.1", each List.Dates([startDate],[Custom],#duration(1, 0, 0, 0))),
#"Expanded Custom.1" = Table.ExpandListColumn(#"Added Custom2", "Custom.1"),
#"Removed Columns" = Table.RemoveColumns(#"Expanded Custom.1",{"startDate", "dueDate", "totalHours", "Custom"}),
#"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"Custom.1", "Date"}, {"ID", "TaskID"}}),
#"Added Index" = Table.AddIndexColumn(#"Renamed Columns", "Index", 0, 1, Int64.Type),
#"Reordered Columns" = Table.ReorderColumns(#"Added Index",{"Index", "TaskID", "Date", "Hours"})
in
#"Reordered Columns"
Please check my sample file for more details.
Best Regards,
Community Support Team _ Eason
@claudeHasler , the first table you can join with date table for second, you can skip join with date table and use measure using the blog
Power BI release plans for 2023 release wave 1 describes all new features releasing from April 2023 through September 2023.
Make sure you register today for the Power BI Summit 2023. Don't miss all of the great sessions and speakers!
Join the biggest FREE Business Applications Event in LATAM this February.
User | Count |
---|---|
216 | |
53 | |
49 | |
46 | |
42 |
User | Count |
---|---|
264 | |
211 | |
113 | |
79 | |
65 |