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

Get Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Request now

Reply
profindir
New Member

Transpose table

Can you help me to transpose this table

tab1.PNG

to that

tab2.PNG

in Power BI Desktop.

 

Thank you.

 

1 ACCEPTED SOLUTION

An alternative solution with far less code can be achieved with more advanced coding, using Table.Partition.

 

let
    Source = Table1,
    #"Added Index" = Table.AddIndexColumn(Source, "Index", 0, 1),
    Partitioned = Table.Partition(#"Added Index","Index",3, each _),
    TableFromColumns = Table.FromColumns(
                            {Partitioned{0}[Column2],
                             Partitioned{0}[Column1],
                             Partitioned{1}[Column1],
                             Partitioned{2}[Column1]}),
    #"Promoted Headers" = Table.PromoteHeaders(TableFromColumns, [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",
                           {{"Invoice Nº", type text},
                            {"Period", type date},
                            {"Sum", type number},
                            {"Quantity", Int64.Type}})
in
    #"Changed Type"

Table.Partition creates a list with separate tables, of which the first table contains all data from the 1st, 4th, 7th etc. row, the second table from the 2nd, 5th, 8th etc row, the third table from the 3rd, 6th, 9th etc. row.

 

Now the appropriate columns can be combined with Table.FromColumns.

Specializing in Power Query Formula Language (M)

View solution in original post

5 REPLIES 5
profindir
New Member

It works. Thank you Smiley Happy

profindir
New Member

tab3.PNG

Edit: refer to the next post for a far more compact, but more advanced solution.

 

My suggestion is to first create separate tables for invoiceNo and for the other columns, both with an index column.

As final result, merge the 2 tables.

Of course, this is to be done in Power Query.

All steps in the queries below are generated via standard menu-options. The pivot step in query OtherColumns was created with advanced option "Don't aggregate".

 

Query InvoiceNo:

let
    Source = Table1,
    #"Removed Columns" = Table.RemoveColumns(Source,{"Column1"}),
    #"Filtered Rows" = Table.SelectRows(#"Removed Columns", each [Column2] <> null and [Column2] <> ""),
    #"Promoted Headers" = Table.PromoteHeaders(#"Filtered Rows", [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"Invoice Nº", type text}}),
    #"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 0, 1)
in
    #"Added Index"

 

Query OtherColumns:

let
    Source = Table1,
    #"Removed Columns2" = Table.RemoveColumns(Source,{"Column2"}),
    #"Added Index" = Table.AddIndexColumn(#"Removed Columns2", "Index", 0, 1),
    #"Integer-Divided Column" = Table.TransformColumns(#"Added Index", {{"Index", each Number.IntegerDivide(_, 3), Int64.Type}}),
    #"Changed Type" = Table.TransformColumnTypes(#"Integer-Divided Column",{{"Index", type text}}),
    #"Added Index1" = Table.AddIndexColumn(#"Changed Type", "Index.1", 0, 1),
    #"Calculated Modulo" = Table.TransformColumns(#"Added Index1", {{"Index.1", each Number.Mod(_, 3), type number}}),
    #"Pivoted Column" = Table.Pivot(#"Calculated Modulo", List.Distinct(#"Calculated Modulo"[Index]), "Index", "Column1"),
    #"Removed Columns1" = Table.RemoveColumns(#"Pivoted Column",{"Index.1"}),
    #"Transposed Table" = Table.Transpose(#"Removed Columns1"),
    #"Promoted Headers" = Table.PromoteHeaders(#"Transposed Table", [PromoteAllScalars=true]),
    #"Added Index2" = Table.AddIndexColumn(#"Promoted Headers", "Index", 0, 1),
    #"Changed Type1" = Table.TransformColumnTypes(#"Added Index2",{{"Period", type date}, {"Sum", type number}, {"Quantity", Int64.Type}})
in
    #"Changed Type1"

Query Result

let
    Source = Table.NestedJoin(InvoiceNo,{"Index"},OtherColumns,{"Index"},"OtherColumns",JoinKind.LeftOuter),
    #"Expanded OtherColumns" = Table.ExpandTableColumn(Source, "OtherColumns", {"Period", "Sum", "Quantity"}, {"Period", "Sum", "Quantity"}),
    #"Removed Columns" = Table.RemoveColumns(#"Expanded OtherColumns",{"Index"})
in
    #"Removed Columns"

 

Specializing in Power Query Formula Language (M)

An alternative solution with far less code can be achieved with more advanced coding, using Table.Partition.

 

let
    Source = Table1,
    #"Added Index" = Table.AddIndexColumn(Source, "Index", 0, 1),
    Partitioned = Table.Partition(#"Added Index","Index",3, each _),
    TableFromColumns = Table.FromColumns(
                            {Partitioned{0}[Column2],
                             Partitioned{0}[Column1],
                             Partitioned{1}[Column1],
                             Partitioned{2}[Column1]}),
    #"Promoted Headers" = Table.PromoteHeaders(TableFromColumns, [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",
                           {{"Invoice Nº", type text},
                            {"Period", type date},
                            {"Sum", type number},
                            {"Quantity", Int64.Type}})
in
    #"Changed Type"

Table.Partition creates a list with separate tables, of which the first table contains all data from the 1st, 4th, 7th etc. row, the second table from the 2nd, 5th, 8th etc row, the third table from the 3rd, 6th, 9th etc. row.

 

Now the appropriate columns can be combined with Table.FromColumns.

Specializing in Power Query Formula Language (M)
MarcelBeug
Community Champion
Community Champion

Please share a picture from your table after import in Power BI (Query Editor).

Specializing in Power Query Formula Language (M)

Helpful resources

Announcements
Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

October Power BI Update Carousel

Power BI Monthly Update - October 2025

Check out the October 2025 Power BI update to learn about new features.

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Top Solution Authors