Microsoft is giving away 50,000 FREE Microsoft Certification exam vouchers!
Enter the sweepstakes now!Prepping for a Fabric certification exam? Join us for a live prep session with exam experts to learn how to pass the exam. Register now.
Hi all,
@amitchandak Could you please help me?!
I have 2 tables in my desktop(see below) and I want to generate desired table based on the 2 tables I have in Power BI.
Date | EmpId | Hours |
11/11/2021 | 100001 | 168 |
3/1/2022 | 100001 | 145 |
5/5/2002 | 100001 | 160 |
1/1/2022 | 100002 | 168 |
EmpId | Name | Hours |
100001 | A | 160 |
100002 | B | 168 |
100003 | C | 164 |
Desired Output table should look like below:
Date | EmpID | EmpName | Contracthours |
1/1/2022 | 100001 | Employee A | 168 |
1/2/2022 | 100001 | Employee A | 168 |
1/3/2022 | 100001 | Employee A | 168 |
1/4/2022 | 100001 | Employee A | 168 |
1/5/2022 | 100001 | Employee A | 168 |
1/6/2022 | 100001 | Employee A | 168 |
1/7/2022 | 100001 | Employee A | 168 |
1/8/2022 | 100001 | Employee A | 168 |
1/9/2022 | 100001 | Employee A | 168 |
1/10/2022 | 100001 | Employee A | 168
|
Till 2/28/2022 | 10001 | A | 168 |
3/1/2022 | 10001 | A | 145 (Till 5/4/2022) |
Any suggestion on this?
Thanks. Have a nice day.
Solved! Go to Solution.
Hi @1320Data ,
Try the following code:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjTUByIjAyNDJR0lQwMgADPMLJRidaKVjPXBckYociamYDlTfVNMOTMDsJwhmj4jmJmxAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t, EmpId = _t, Hours = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Date", type date}, {"EmpId", Int64.Type}, {"Hours", Int64.Type}}),
#"Sorted Rows" = Table.Sort(#"Changed Type",{{"EmpId", Order.Ascending}, {"Date", Order.Ascending}}),
#"Added Index" = Table.AddIndexColumn(#"Sorted Rows", "Index", 0, 1, Int64.Type),
#"Added Custom" = Table.AddColumn(#"Added Index", "Custom", each try if [EmpId] = #"Added Index" [EmpId] {[Index] + 1} then #"Added Index" [Date] {[Index] + 1} else null otherwise null),
#"Added Custom1" = Table.AddColumn(#"Added Custom", "Custom.1", each try {0.. Duration.Days([Custom] - [Date] ) } otherwise null),
#"Expanded Custom.1" = Table.ExpandListColumn(#"Added Custom1", "Custom.1"),
#"Added Custom2" = Table.AddColumn(#"Expanded Custom.1", "Custom.2", each try [Date] + #duration([Custom.1],0,0,0) otherwise [Date]),
#"Removed Columns" = Table.RemoveColumns(#"Added Custom2",{"Index", "Custom", "Custom.1", "Date"}),
#"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"Custom.2", "Date"}}),
#"Sorted Rows1" = Table.Sort(#"Renamed Columns",{{"Date", Order.Ascending}})
in
#"Sorted Rows1"
Regards
Miguel Félix
Proud to be a Super User!
Check out my blog: Power BI em PortuguêsThank you. I did the same by creating index column and self join the table. It worked.
Thank you. I did the same by creating index column and self join the table. It worked.
Hi @1320Data ,
Try the following code:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjTUByIjAyNDJR0lQwMgADPMLJRidaKVjPXBckYociamYDlTfVNMOTMDsJwhmj4jmJmxAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t, EmpId = _t, Hours = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Date", type date}, {"EmpId", Int64.Type}, {"Hours", Int64.Type}}),
#"Sorted Rows" = Table.Sort(#"Changed Type",{{"EmpId", Order.Ascending}, {"Date", Order.Ascending}}),
#"Added Index" = Table.AddIndexColumn(#"Sorted Rows", "Index", 0, 1, Int64.Type),
#"Added Custom" = Table.AddColumn(#"Added Index", "Custom", each try if [EmpId] = #"Added Index" [EmpId] {[Index] + 1} then #"Added Index" [Date] {[Index] + 1} else null otherwise null),
#"Added Custom1" = Table.AddColumn(#"Added Custom", "Custom.1", each try {0.. Duration.Days([Custom] - [Date] ) } otherwise null),
#"Expanded Custom.1" = Table.ExpandListColumn(#"Added Custom1", "Custom.1"),
#"Added Custom2" = Table.AddColumn(#"Expanded Custom.1", "Custom.2", each try [Date] + #duration([Custom.1],0,0,0) otherwise [Date]),
#"Removed Columns" = Table.RemoveColumns(#"Added Custom2",{"Index", "Custom", "Custom.1", "Date"}),
#"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"Custom.2", "Date"}}),
#"Sorted Rows1" = Table.Sort(#"Renamed Columns",{{"Date", Order.Ascending}})
in
#"Sorted Rows1"
Regards
Miguel Félix
Proud to be a Super User!
Check out my blog: Power BI em PortuguêsCheck out the April 2025 Power BI update to learn about new features.
Explore and share Fabric Notebooks to boost Power BI insights in the new community notebooks gallery.
User | Count |
---|---|
72 | |
67 | |
67 | |
44 | |
42 |
User | Count |
---|---|
47 | |
38 | |
28 | |
27 | |
27 |