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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
btcar94
New Member

Merge multiple columns into single column with multiple rows

How do I merge multiple columns into a single column with multiple rows? The first image is what i have and the second is what i want. 

 

LocationObservation 1Risk 1Observation 2Risk 2Observation 3Risk 3
MexicoShippingProcessSalesProcessInventoryProcess
USAInventoryDOAExpenseDOAPO ProcessDOA
ArgentinaPO ProcessProcessInventoryProcessExpenseProcess

 

 

LocationObservation #ObservationRisk
Mexico1ShippingProcess
Mexico2SalesProcess
Mexico3InventoryProcess
USA1InventoryDOA
USA2ExpenseDOA
USA3PO ProcessDOA
Argentina1PO ProcessProcess
Argentina2InventoryProcess
Argentina3ExpenseProcess
3 ACCEPTED SOLUTIONS
jgeddes
Super User
Super User

There are a few ways to do this. 
Here is an example code you can paste into the advanced editor of a blank query and then follow though the steps.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8k2tyEzOV9JRCs7ILCjIzEsHMgOK8pNTi4tBgok5qcUoIp55Zal5JflFlUiisTrRSqHBjmiyLv4gEdeKgtS84lQ4P8BfAWEYSAik2bEoHagtMy8RXQF+e5FNh7slFgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Location = _t, #"Observation 1" = _t, #"Risk 1" = _t, #"Observation 2" = _t, #"Risk 2" = _t, #"Observation 3" = _t, #"Risk 3" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Location", type text}, {"Observation 1", type text}, {"Risk 1", type text}, {"Observation 2", type text}, {"Risk 2", type text}, {"Observation 3", type text}, {"Risk 3", type text}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Location"}, "Observation Number", "Value"),
    #"Extracted Text After Delimiter" = Table.TransformColumns(#"Unpivoted Other Columns", {{"Observation Number", each Text.AfterDelimiter(_, " "), type text}}),
    #"Grouped Rows" = Table.Group(#"Extracted Text After Delimiter", {"Location", "Observation Number"}, {{"_nestedTable", each Table.SelectColumns(_, {"Value"}), type table [Location=nullable text, Observation=text, Value=text]}}),
    Custom1 = Table.TransformColumns(#"Grouped Rows", {{"_nestedTable", each Table.Transpose(_)}}),
    #"Expanded _nestedTable" = Table.ExpandTableColumn(Custom1, "_nestedTable", {"Column1", "Column2"}, {"Observation", "Risk"})
in
    #"Expanded _nestedTable"




Did I answer your question? Mark my post as a solution!

Proud to be a Super User!





View solution in original post

Anonymous
Not applicable

Hi @btcar94 

 

Thanks to @jgeddes  for the excellent solution. 

Here is an alternative solution if you have interest:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8k2tyEzOV9JRCs7ILCjIzEsHMgOK8pNTi4tBgok5qcUoIp55Zal5JflFlUiisTrRSqHBjmiyLv4gEdeKgtS84lQ4P8BfAWEYSAik2bEoHagtMy8RXQF+e5FNh7slFgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Location = _t, #"Observation 1" = _t, #"Risk 1" = _t, #"Observation 2" = _t, #"Risk 2" = _t, #"Observation 3" = _t, #"Risk 3" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Location", type text}, {"Observation 1", type text}, {"Risk 1", type text}, {"Observation 2", type text}, {"Risk 2", type text}, {"Observation 3", type text}, {"Risk 3", type text}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each Table.AddIndexColumn(Table.FromRows(List.Split(List.RemoveFirstN(Record.ToList(_),1),2), {"Observation","Risk"}),"Observation #",1,1)),
    #"Removed Other Columns" = Table.SelectColumns(#"Added Custom",{"Location", "Custom"}),
    #"Expanded Custom" = Table.ExpandTableColumn(#"Removed Other Columns", "Custom", {"Observation", "Risk", "Observation #"}, {"Observation", "Risk", "Observation #"}),
    #"Reordered Columns" = Table.ReorderColumns(#"Expanded Custom",{"Location", "Observation #", "Observation", "Risk"})
in
    #"Reordered Columns"

 

The first and key step is to add a custom column with below code. Then remove columns from "Observation 1" to "Risk 3". Expand the custom column and reorder columns. 

Table.AddIndexColumn(Table.FromRows(List.Split(List.RemoveFirstN(Record.ToList(_),1),2), {"Observation","Risk"}),"Observation #",1,1)

vjingzhanmsft_0-1712646889516.png

vjingzhanmsft_1-1712647134488.png

 

Best Regards,
Jing
If this post helps, please Accept it as Solution to help other members find it. Appreciate your Kudos!

View solution in original post

AlienSx
Super User
Super User

let
    Source = what_you_have,
    unpivot = Table.UnpivotOtherColumns(Source, {"Location"}, "Attribute", "Value"),
    split = Table.SplitColumn(
        unpivot, "Attribute", 
        Splitter.SplitTextByEachDelimiter({" "}, QuoteStyle.Csv, false), 
        {"Attribute.1", "Observation #"}
    ),
    pivot = Table.Pivot(
        split, 
        List.Distinct(split[Attribute.1]), 
        "Attribute.1", "Value"
    )
in
    pivot

View solution in original post

3 REPLIES 3
AlienSx
Super User
Super User

let
    Source = what_you_have,
    unpivot = Table.UnpivotOtherColumns(Source, {"Location"}, "Attribute", "Value"),
    split = Table.SplitColumn(
        unpivot, "Attribute", 
        Splitter.SplitTextByEachDelimiter({" "}, QuoteStyle.Csv, false), 
        {"Attribute.1", "Observation #"}
    ),
    pivot = Table.Pivot(
        split, 
        List.Distinct(split[Attribute.1]), 
        "Attribute.1", "Value"
    )
in
    pivot
Anonymous
Not applicable

Hi @btcar94 

 

Thanks to @jgeddes  for the excellent solution. 

Here is an alternative solution if you have interest:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8k2tyEzOV9JRCs7ILCjIzEsHMgOK8pNTi4tBgok5qcUoIp55Zal5JflFlUiisTrRSqHBjmiyLv4gEdeKgtS84lQ4P8BfAWEYSAik2bEoHagtMy8RXQF+e5FNh7slFgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Location = _t, #"Observation 1" = _t, #"Risk 1" = _t, #"Observation 2" = _t, #"Risk 2" = _t, #"Observation 3" = _t, #"Risk 3" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Location", type text}, {"Observation 1", type text}, {"Risk 1", type text}, {"Observation 2", type text}, {"Risk 2", type text}, {"Observation 3", type text}, {"Risk 3", type text}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each Table.AddIndexColumn(Table.FromRows(List.Split(List.RemoveFirstN(Record.ToList(_),1),2), {"Observation","Risk"}),"Observation #",1,1)),
    #"Removed Other Columns" = Table.SelectColumns(#"Added Custom",{"Location", "Custom"}),
    #"Expanded Custom" = Table.ExpandTableColumn(#"Removed Other Columns", "Custom", {"Observation", "Risk", "Observation #"}, {"Observation", "Risk", "Observation #"}),
    #"Reordered Columns" = Table.ReorderColumns(#"Expanded Custom",{"Location", "Observation #", "Observation", "Risk"})
in
    #"Reordered Columns"

 

The first and key step is to add a custom column with below code. Then remove columns from "Observation 1" to "Risk 3". Expand the custom column and reorder columns. 

Table.AddIndexColumn(Table.FromRows(List.Split(List.RemoveFirstN(Record.ToList(_),1),2), {"Observation","Risk"}),"Observation #",1,1)

vjingzhanmsft_0-1712646889516.png

vjingzhanmsft_1-1712647134488.png

 

Best Regards,
Jing
If this post helps, please Accept it as Solution to help other members find it. Appreciate your Kudos!

jgeddes
Super User
Super User

There are a few ways to do this. 
Here is an example code you can paste into the advanced editor of a blank query and then follow though the steps.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8k2tyEzOV9JRCs7ILCjIzEsHMgOK8pNTi4tBgok5qcUoIp55Zal5JflFlUiisTrRSqHBjmiyLv4gEdeKgtS84lQ4P8BfAWEYSAik2bEoHagtMy8RXQF+e5FNh7slFgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Location = _t, #"Observation 1" = _t, #"Risk 1" = _t, #"Observation 2" = _t, #"Risk 2" = _t, #"Observation 3" = _t, #"Risk 3" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Location", type text}, {"Observation 1", type text}, {"Risk 1", type text}, {"Observation 2", type text}, {"Risk 2", type text}, {"Observation 3", type text}, {"Risk 3", type text}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Location"}, "Observation Number", "Value"),
    #"Extracted Text After Delimiter" = Table.TransformColumns(#"Unpivoted Other Columns", {{"Observation Number", each Text.AfterDelimiter(_, " "), type text}}),
    #"Grouped Rows" = Table.Group(#"Extracted Text After Delimiter", {"Location", "Observation Number"}, {{"_nestedTable", each Table.SelectColumns(_, {"Value"}), type table [Location=nullable text, Observation=text, Value=text]}}),
    Custom1 = Table.TransformColumns(#"Grouped Rows", {{"_nestedTable", each Table.Transpose(_)}}),
    #"Expanded _nestedTable" = Table.ExpandTableColumn(Custom1, "_nestedTable", {"Column1", "Column2"}, {"Observation", "Risk"})
in
    #"Expanded _nestedTable"




Did I answer your question? Mark my post as a solution!

Proud to be a Super User!





Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

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.