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

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
Anonymous
Not applicable

Structuring data into desired format with pivoting/unpivoting

Hi everyone,
I have a dataset of hours worked by some users that is structured in this format
Hours.PNG

I woul like to transform it in this format 
hour s 2.PNG

What kind of PowerQuery operations do I have to perform to get this result?
Thanks

2 ACCEPTED SOLUTIONS
HotChilli
Super User
Super User

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.

View solution in original post

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"

 

 



Follow on LinkedIn
@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
Power BI Cookbook Third Edition (Color)

DAX is easy, CALCULATE makes DAX hard...

View solution in original post

2 REPLIES 2
HotChilli
Super User
Super User

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"

 

 



Follow on LinkedIn
@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
Power BI Cookbook Third Edition (Color)

DAX is easy, CALCULATE makes DAX hard...

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

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

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

Check out the November 2024 Power BI update to learn about new features.