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
Lyvili
Frequent Visitor

Transform in columns (transpone, unpivot..)

Good afternoon, 

I am trying to solve this topic through several ways in PowerQuery. Unfortunately I could not. Could you please assist me?

Thanks in advance!

 

Original:

Original.jpg

 

TO BE:

To_be.jpg

1 ACCEPTED SOLUTION
ronrsnfld
Super User
Super User

Your data appears to be a single table. So:

  • Split the table at the first null row
  • Pivot Part 1
  • Add the pivoted Part 1 to each row of Part 2
let
    Source = Excel.CurrentWorkbook(){[Name="Table4"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{
        {"Column1", type text}, {"Column2", type any}, {"Column3", type text}, {"Column4", type text}, {"Column5", type text},
        {"Column6", type any}, {"Column7", type text}, {"Column8", type text}}),

    #"Split Table" = Table.SplitAt(#"Changed Type", List.PositionOf(#"Changed Type"[Column1],null, Occurrence.First)),
    Part1 = Table.SelectColumns(#"Split Table"{0}, 
                List.FirstN(Table.ColumnNames(#"Split Table"{0}),2)),
    Part2 = Table.PromoteHeaders(Table.RemoveFirstN(#"Split Table"{1},1),[PromoteAllScalars=true, Culture="en-US"]),

    #"Pivot Part1" = Table.Pivot(Part1, Part1[Column1], "Column1","Column2"),
    #"Combine Part2" = Table.AddColumn(Part2, "Part1", each #"Pivot Part1", type table),
    #"Reordered Columns" = Table.ReorderColumns(#"Combine Part2",{"Part1", "ID", "ID A", "ID K", "ID M", "ID G", "Nivel", "Dept", "Centro"}),
    #"Expanded Part1" = Table.ExpandTableColumn(#"Reordered Columns", "Part1", {"Агеа de planificacion", "Fесћа", "С447 -FKA", "C447 -FKB", "С447 -FLK"}, {"Агеа de planificacion", "Fесћа", "С447 -FKA", "C447 -FKB", "С447 -FLK"})
in
    #"Expanded Part1"

 

Source

ronrsnfld_0-1708723569168.png

 

Results

ronrsnfld_1-1708723602489.png

+

 

View solution in original post

3 REPLIES 3
dufoq3
Super User
Super User

Hi @Lyvili, different approach. This one should be dynamic

 

Result:

dufoq3_0-1709400535114.png

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("fY7BCoMwEER/JeRcJRu19hoVQcSeBREJNqUBUREp/fxu1LZWRDbLbGbfhBQFFYOS5KZI38hW33Uta9219ERFMyqJ+nfKU0FjVT/MgoENzOaMO3tU6Lo+seJUoMHPR0SABrhHRIjGZQ/YeoudRDglERGzpLNkKFf9VA1qpPoRJVTtOHRTJq+mQvO1aoadBfB5GKrcwjIfXkGwhQCAVz8ObwvJvyR4vuWZxSoBm4SZnJ1E+QY=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t, Column3 = _t, Column4 = _t, Column5 = _t, Column6 = _t, Column7 = _t]),
    UpperInfo = Table.FirstN(Source, each [Column1] <> "" and [Column1] <> null),
    UpperInfoRows = List.Transform(Table.ToRows(UpperInfo), each List.Select(_, (x)=> x <> null and x <> "")),
    StepBack = Source,
    LowerData = Table.PromoteHeaders(Table.SelectRows(Table.Skip(StepBack, each [Column1] <> null and [Column1] <> ""), (x)=> x[Column1] <> null and x[Column1] <> "")),
    FinalTable = List.Accumulate( 
     UpperInfoRows,
     LowerData,
     (s,c)=> Table.AddColumn(s, c{0}, each c{1})
     ),
    ReorderedColumns = Table.ReorderColumns(FinalTable, UpperInfo[Column1] & Table.ColumnNames(LowerData))
in
    ReorderedColumns

 


Note: Check this link to learn how to use my query.
Check this link if you don't know how to provide sample data.

Lyvili
Frequent Visitor

Thank you very much @ronrsnfld 

ronrsnfld
Super User
Super User

Your data appears to be a single table. So:

  • Split the table at the first null row
  • Pivot Part 1
  • Add the pivoted Part 1 to each row of Part 2
let
    Source = Excel.CurrentWorkbook(){[Name="Table4"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{
        {"Column1", type text}, {"Column2", type any}, {"Column3", type text}, {"Column4", type text}, {"Column5", type text},
        {"Column6", type any}, {"Column7", type text}, {"Column8", type text}}),

    #"Split Table" = Table.SplitAt(#"Changed Type", List.PositionOf(#"Changed Type"[Column1],null, Occurrence.First)),
    Part1 = Table.SelectColumns(#"Split Table"{0}, 
                List.FirstN(Table.ColumnNames(#"Split Table"{0}),2)),
    Part2 = Table.PromoteHeaders(Table.RemoveFirstN(#"Split Table"{1},1),[PromoteAllScalars=true, Culture="en-US"]),

    #"Pivot Part1" = Table.Pivot(Part1, Part1[Column1], "Column1","Column2"),
    #"Combine Part2" = Table.AddColumn(Part2, "Part1", each #"Pivot Part1", type table),
    #"Reordered Columns" = Table.ReorderColumns(#"Combine Part2",{"Part1", "ID", "ID A", "ID K", "ID M", "ID G", "Nivel", "Dept", "Centro"}),
    #"Expanded Part1" = Table.ExpandTableColumn(#"Reordered Columns", "Part1", {"Агеа de planificacion", "Fесћа", "С447 -FKA", "C447 -FKB", "С447 -FLK"}, {"Агеа de planificacion", "Fесћа", "С447 -FKA", "C447 -FKB", "С447 -FLK"})
in
    #"Expanded Part1"

 

Source

ronrsnfld_0-1708723569168.png

 

Results

ronrsnfld_1-1708723602489.png

+

 

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.