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

Don't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.

Reply
Saes
Helper I
Helper I

Unpivot / transpose / amend a Single Row

Hi all, I have a multiple datasets (about 20 tables) that look like this - annoyingly the output puts the units in row 2.

Sub CompanyMeasure 1Measure 2Measure 3
UnitsNumber%Number
Company 1100.510
Company 2200.620
Company 3300.730
Company 4400.840
Company 5500.950

 

I would like to clean the data so that the data looks as follows, but I cannot work out how to unpivot / transpose / amend the unit row, before unpivotting the measure columns.

 

Sub CompanyUnitsAttributeValue
Company 1NumberMeasure 110
Company 1%Measure 20.5
Company 1NumberMeasure 1=310
Company 2NumberMeasure 120
Company 2%Measure 20.6
Company 2NumberMeasure 1=320

 

Can anyone help?

1 ACCEPTED SOLUTION
serpiva64
Solution Sage
Solution Sage

Hi, 

you can obtain this

serpiva64_1-1688723521598.png

 

by

- demote headers

- transpose table

- promote headers

- unpivot columns

let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCs3LLClW0lHyK81NSi0CMlQRnFidaCXn/NyCxLxKBUOgsKEBkDDQM4UwkWWNgEJGEFkzCBNZ1hgoZAyRNYcwkWVNgEImEFkLCBNZFmSZKUTWEsKMjQUA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Sub Company" = _t, #"Measure 1" = _t, #"Measure 2" = _t, #"Measure 3" = _t]),
#"Demoted Headers" = Table.DemoteHeaders(Source),
#"Transposed Table" = Table.Transpose(#"Demoted Headers"),
#"Promoted Headers" = Table.PromoteHeaders(#"Transposed Table", [PromoteAllScalars=true]),
#"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Promoted Headers", {"Sub Company", "Units"}, "Attribute", "Value"),
#"Renamed Columns" = Table.RenameColumns(#"Unpivoted Columns",{{"Attribute", "SubCompany"}, {"Sub Company", "Attribute"}}),
#"Sorted Rows" = Table.Sort(#"Renamed Columns",{{"SubCompany", Order.Ascending},{"Attribute", Order.Ascending}}),
#"Reordered Columns" = Table.ReorderColumns(#"Sorted Rows",{"SubCompany", "Units", "Attribute", "Value"})
in
#"Reordered Columns"

 

If this post is useful to help you to solve your issue consider giving the post a thumbs up 

 and accepting it as a solution !

 

View solution in original post

3 REPLIES 3
Saes
Helper I
Helper I

Thanks @serpiva64 - that worked perfectly. Thank you!

serpiva64
Solution Sage
Solution Sage

Hi, 

you can obtain this

serpiva64_1-1688723521598.png

 

by

- demote headers

- transpose table

- promote headers

- unpivot columns

let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCs3LLClW0lHyK81NSi0CMlQRnFidaCXn/NyCxLxKBUOgsKEBkDDQM4UwkWWNgEJGEFkzCBNZ1hgoZAyRNYcwkWVNgEImEFkLCBNZFmSZKUTWEsKMjQUA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Sub Company" = _t, #"Measure 1" = _t, #"Measure 2" = _t, #"Measure 3" = _t]),
#"Demoted Headers" = Table.DemoteHeaders(Source),
#"Transposed Table" = Table.Transpose(#"Demoted Headers"),
#"Promoted Headers" = Table.PromoteHeaders(#"Transposed Table", [PromoteAllScalars=true]),
#"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Promoted Headers", {"Sub Company", "Units"}, "Attribute", "Value"),
#"Renamed Columns" = Table.RenameColumns(#"Unpivoted Columns",{{"Attribute", "SubCompany"}, {"Sub Company", "Attribute"}}),
#"Sorted Rows" = Table.Sort(#"Renamed Columns",{{"SubCompany", Order.Ascending},{"Attribute", Order.Ascending}}),
#"Reordered Columns" = Table.ReorderColumns(#"Sorted Rows",{"SubCompany", "Units", "Attribute", "Value"})
in
#"Reordered Columns"

 

If this post is useful to help you to solve your issue consider giving the post a thumbs up 

 and accepting it as a solution !

 

BA_Pete
Super User
Super User

Hi @Saes ,

 

Here's one way to do it. It involves a few custom steps/adjustments but is fairly simple and tidy:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCs3LLClW0lHyK81NSi0CMlQRnFidaCXn/NyCxLxKBUOgsKEBkDDQM4UwkWWNgEJGEFkzCBNZ1hgoZAyRNYcwkWVNgEImEFkLCBNZFmSZKUTWEsKMjQUA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Sub Company" = _t, #"Measure 1" = _t, #"Measure 2" = _t, #"Measure 3" = _t]),
    unpivOthCols = Table.UnpivotOtherColumns(Source, {"Sub Company"}, "Attribute", "Value"),
    getUnitsTable = Table.SelectRows(unpivOthCols, each [Sub Company] = "Units"),
    getDataTable = Table.SelectRows(unpivOthCols, each [Sub Company] <> "Units"),
    mergeUnitsOnData = Table.NestedJoin(getDataTable, {"Attribute"}, getUnitsTable, {"Attribute"}, "getDataTable", JoinKind.LeftOuter),
    expandUnitsValue = Table.ExpandTableColumn(mergeUnitsOnData, "getDataTable", {"Value"}, {"Value.1"})
in
    expandUnitsValue

 

Summary:

-1- Unpivot columns other than [Sub Company]

-2- Split into two tables, one with just [Sub Company] = "Units", the other with everything else

-3- Merge Units table onto Other Data table on U.Attribute = OD.Attribute

-4- Expand OD.Value

 

Output:

BA_Pete_0-1688722991004.png

 

Pete



Now accepting Kudos! If my post helped you, why not give it a thumbs-up?

Proud to be a Datanaut!




Helpful resources

Announcements
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! Prices go up Feb. 11th.

Jan25PBI_Carousel

Power BI Monthly Update - January 2025

Check out the January 2025 Power BI update to learn about new features in Reporting, Modeling, and Data Connectivity.

Jan NL Carousel

Fabric Community Update - January 2025

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