Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!Calling all Data Engineers! Fabric Data Engineer (Exam DP-700) live sessions are back! Starting October 16th. Sign up.
Hi everyone,
I have a dataset of hours worked by some users that is structured in this format
I woul like to transform it in this format
What kind of PowerQuery operations do I have to perform to get this result?
Thanks
Solved! Go to Solution.
Select all the Day columns and Unpivot them.
Select the Type column and Pivot it using the newly created Value column as the Value,
Split the Day column by the left 3 characters. Tidy up the columns by removing the ones you don't want and renaming the ones that need it.
I followed @HotChilli's instructions and I believe I got the exact result after I unpivoted the Day columns and then Pivoted the Type column using Value. Attached PBIX, here is the query code:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQyVtJRCsnPBZLh+UXZQMoCBcfqoCpyKkpNBKkyBGIjKG2IoSo4Mzk7L7W4GMg0QMEghSamZkC2V2pRUSXCVnMkW82xKEO21xDFXlR1uG2OBQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [WorkedID = _t, Name = _t, Type = _t, Day1 = _t, Day2 = _t, Day3 = _t, Day4 = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"WorkedID", Int64.Type}, {"Name", type text}, {"Type", type text}, {"Day1", Int64.Type}, {"Day2", Int64.Type}, {"Day3", Int64.Type}, {"Day4", Int64.Type}}),
#"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"WorkedID", "Name", "Type"}, "Attribute", "Value"),
#"Pivoted Column" = Table.Pivot(#"Unpivoted Columns", List.Distinct(#"Unpivoted Columns"[Type]), "Type", "Value", List.Sum)
in
#"Pivoted Column"
Select all the Day columns and Unpivot them.
Select the Type column and Pivot it using the newly created Value column as the Value,
Split the Day column by the left 3 characters. Tidy up the columns by removing the ones you don't want and renaming the ones that need it.
I followed @HotChilli's instructions and I believe I got the exact result after I unpivoted the Day columns and then Pivoted the Type column using Value. Attached PBIX, here is the query code:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQyVtJRCsnPBZLh+UXZQMoCBcfqoCpyKkpNBKkyBGIjKG2IoSo4Mzk7L7W4GMg0QMEghSamZkC2V2pRUSXCVnMkW82xKEO21xDFXlR1uG2OBQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [WorkedID = _t, Name = _t, Type = _t, Day1 = _t, Day2 = _t, Day3 = _t, Day4 = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"WorkedID", Int64.Type}, {"Name", type text}, {"Type", type text}, {"Day1", Int64.Type}, {"Day2", Int64.Type}, {"Day3", Int64.Type}, {"Day4", Int64.Type}}),
#"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"WorkedID", "Name", "Type"}, "Attribute", "Value"),
#"Pivoted Column" = Table.Pivot(#"Unpivoted Columns", List.Distinct(#"Unpivoted Columns"[Type]), "Type", "Value", List.Sum)
in
#"Pivoted Column"
Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes!
Check out the October 2025 Power BI update to learn about new features.