Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!Calling all Data Engineers! Fabric Data Engineer (Exam DP-700) live sessions are back! Starting October 16th. Sign up.
Let's say I have the following table:
City | Date | Product1 | Quantity1 | Product2 | Quantity2 | Product3 | Quantity3 |
Dallas | 9/11 | Wood | 45 | Wheat | 32 | Ore | 21 |
Austin | 9/12 | Ore | 31 | Wood | 20 | *blank* | blank* |
Houston | 9/13 | Wheat | 42 | Wood | 17 | *blank* | *blank* |
I want to create a table that looks like this:
City | Date | Product | Product Name | Quantity |
Dallas | 9/11 | 1 | Wood | 45 |
Dallas | 9/11 | 2 | Wheat | 32 |
Dallas | 9/11 | 3 | Ore | 21 |
Austin | 9/12 | 1 | Ore | 31 |
Austin | 9/12 | 2 | Wood | 20 |
Houston | 9/13 | 1 | Wheat | 42 |
Houston | 9/13 | 2 | Wood | 17 |
How do I create a table like this using DAX / power BI? I've been pretty stuck on it.
Solved! Go to Solution.
Hi @BBHouston ,
Please refer to the M query below:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcknMyUksVtJRstQ3NARS4fn5KUDKxBTEzkhNLAHSxkZAwr8oFUgaGSrF6kQrOZYWl2TmQXQhJI2RDDAyABIgBFLukQ9Unw9Vb4xksokRQoehOUxHLAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [City = _t, Date = _t, Product1 = _t, Quantity1 = _t, Product2 = _t, Quantity2 = _t, Product3 = _t, Quantity3 = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"City", type text}, {"Date", type date}, {"Product1", type text}, {"Quantity1", Int64.Type}, {"Product2", type text}, {"Quantity2", Int64.Type}, {"Product3", type text}, {"Quantity3", Int64.Type}}),
#"Replaced Value" = Table.ReplaceValue(#"Changed Type","",null,Replacer.ReplaceValue,{"Product3"}),
#"Merged Columns" = Table.CombineColumns(Table.TransformColumnTypes(#"Replaced Value", {{"Quantity1", type text}}, "en-US"),{"Product1", "Quantity1"},Combiner.CombineTextByDelimiter(",", QuoteStyle.None),"Merged"),
#"Merged Columns1" = Table.CombineColumns(Table.TransformColumnTypes(#"Merged Columns", {{"Quantity2", type text}}, "en-US"),{"Product2", "Quantity2"},Combiner.CombineTextByDelimiter(",", QuoteStyle.None),"Merged.1"),
#"Merged Columns2" = Table.CombineColumns(Table.TransformColumnTypes(#"Merged Columns1", {{"Quantity3", type text}}, "en-US"),{"Product3", "Quantity3"},Combiner.CombineTextByDelimiter(",", QuoteStyle.None),"Merged.2"),
#"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Merged Columns2", {"City", "Date"}, "Attribute", "Value"),
#"Split Column by Delimiter" = Table.SplitColumn(#"Unpivoted Columns", "Value", Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv), {"Value.1", "Value.2"}),
#"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Value.1", type text}, {"Value.2", type text}}),
#"Removed Columns" = Table.RemoveColumns(#"Changed Type1",{"Attribute"}),
#"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"Value.1", "Product Name"}, {"Value.2", "Quantity"}}),
#"Filtered Rows" = Table.SelectRows(#"Renamed Columns", each ([Product Name] <> "")),
#"Grouped Rows" = Table.Group(#"Filtered Rows", {"City"}, {{"table", each _, type table [City=nullable text, Date=nullable date, Product Name=nullable text, Quantity=nullable text]}}),
RankFunction = (table1 as table) as table =>
let
AddIndex = Table.AddIndexColumn(table1, "Product", 1, 1)
in
AddIndex,
#"AddedRank" = Table.TransformColumns(#"Grouped Rows", {"table", each RankFunction(_)}),
#"Expanded table" = Table.ExpandTableColumn(AddedRank, "table", {"Date", "Product Name", "Quantity", "Product"}, {"table.Date", "table.Product Name", "table.Quantity", "table.Product"}),
#"Renamed Columns1" = Table.RenameColumns(#"Expanded table",{{"table.Product Name", "Product Name"}, {"table.Quantity", "Quantity"}, {"table.Product", "Product"}}),
#"Reordered Columns" = Table.ReorderColumns(#"Renamed Columns1",{"City", "table.Date", "Product", "Product Name", "Quantity"}),
#"Renamed Columns2" = Table.RenameColumns(#"Reordered Columns",{{"table.Date", "Date"}})
in
#"Renamed Columns2"
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Best Regards,
Dedmon Dai
Hi,
This M code works
let
Source = Excel.CurrentWorkbook(){[Name="Data"]}[Content],
#"Changed Type" = Table.TransformColumnTypes(Source,{{"City", type text}, {"Date", type datetime}, {"Product1", type text}, {"Quantity1", Int64.Type}, {"Product2", type text}, {"Quantity2", Int64.Type}, {"Product3", type text}, {"Quantity3", Int64.Type}}),
#"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"City", "Date"}, "Attribute", "Value"),
#"Split Column by Character Transition" = Table.SplitColumn(#"Unpivoted Other Columns", "Attribute", Splitter.SplitTextByCharacterTransition((c) => not List.Contains({"0".."9"}, c), {"0".."9"}), {"Attribute.1", "Attribute.2"}),
#"Pivoted Column" = Table.Pivot(#"Split Column by Character Transition", List.Distinct(#"Split Column by Character Transition"[Attribute.1]), "Attribute.1", "Value"),
#"Sorted Rows" = Table.Sort(#"Pivoted Column",{{"Date", Order.Ascending}, {"City", Order.Ascending}, {"Attribute.2", Order.Ascending}})
in
#"Sorted Rows"
Hope this helps.
Hi,
This M code works
let
Source = Excel.CurrentWorkbook(){[Name="Data"]}[Content],
#"Changed Type" = Table.TransformColumnTypes(Source,{{"City", type text}, {"Date", type datetime}, {"Product1", type text}, {"Quantity1", Int64.Type}, {"Product2", type text}, {"Quantity2", Int64.Type}, {"Product3", type text}, {"Quantity3", Int64.Type}}),
#"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"City", "Date"}, "Attribute", "Value"),
#"Split Column by Character Transition" = Table.SplitColumn(#"Unpivoted Other Columns", "Attribute", Splitter.SplitTextByCharacterTransition((c) => not List.Contains({"0".."9"}, c), {"0".."9"}), {"Attribute.1", "Attribute.2"}),
#"Pivoted Column" = Table.Pivot(#"Split Column by Character Transition", List.Distinct(#"Split Column by Character Transition"[Attribute.1]), "Attribute.1", "Value"),
#"Sorted Rows" = Table.Sort(#"Pivoted Column",{{"Date", Order.Ascending}, {"City", Order.Ascending}, {"Attribute.2", Order.Ascending}})
in
#"Sorted Rows"
Hope this helps.
Hi @BBHouston ,
Please refer to the M query below:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcknMyUksVtJRstQ3NARS4fn5KUDKxBTEzkhNLAHSxkZAwr8oFUgaGSrF6kQrOZYWl2TmQXQhJI2RDDAyABIgBFLukQ9Unw9Vb4xksokRQoehOUxHLAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [City = _t, Date = _t, Product1 = _t, Quantity1 = _t, Product2 = _t, Quantity2 = _t, Product3 = _t, Quantity3 = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"City", type text}, {"Date", type date}, {"Product1", type text}, {"Quantity1", Int64.Type}, {"Product2", type text}, {"Quantity2", Int64.Type}, {"Product3", type text}, {"Quantity3", Int64.Type}}),
#"Replaced Value" = Table.ReplaceValue(#"Changed Type","",null,Replacer.ReplaceValue,{"Product3"}),
#"Merged Columns" = Table.CombineColumns(Table.TransformColumnTypes(#"Replaced Value", {{"Quantity1", type text}}, "en-US"),{"Product1", "Quantity1"},Combiner.CombineTextByDelimiter(",", QuoteStyle.None),"Merged"),
#"Merged Columns1" = Table.CombineColumns(Table.TransformColumnTypes(#"Merged Columns", {{"Quantity2", type text}}, "en-US"),{"Product2", "Quantity2"},Combiner.CombineTextByDelimiter(",", QuoteStyle.None),"Merged.1"),
#"Merged Columns2" = Table.CombineColumns(Table.TransformColumnTypes(#"Merged Columns1", {{"Quantity3", type text}}, "en-US"),{"Product3", "Quantity3"},Combiner.CombineTextByDelimiter(",", QuoteStyle.None),"Merged.2"),
#"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Merged Columns2", {"City", "Date"}, "Attribute", "Value"),
#"Split Column by Delimiter" = Table.SplitColumn(#"Unpivoted Columns", "Value", Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv), {"Value.1", "Value.2"}),
#"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Value.1", type text}, {"Value.2", type text}}),
#"Removed Columns" = Table.RemoveColumns(#"Changed Type1",{"Attribute"}),
#"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"Value.1", "Product Name"}, {"Value.2", "Quantity"}}),
#"Filtered Rows" = Table.SelectRows(#"Renamed Columns", each ([Product Name] <> "")),
#"Grouped Rows" = Table.Group(#"Filtered Rows", {"City"}, {{"table", each _, type table [City=nullable text, Date=nullable date, Product Name=nullable text, Quantity=nullable text]}}),
RankFunction = (table1 as table) as table =>
let
AddIndex = Table.AddIndexColumn(table1, "Product", 1, 1)
in
AddIndex,
#"AddedRank" = Table.TransformColumns(#"Grouped Rows", {"table", each RankFunction(_)}),
#"Expanded table" = Table.ExpandTableColumn(AddedRank, "table", {"Date", "Product Name", "Quantity", "Product"}, {"table.Date", "table.Product Name", "table.Quantity", "table.Product"}),
#"Renamed Columns1" = Table.RenameColumns(#"Expanded table",{{"table.Product Name", "Product Name"}, {"table.Quantity", "Quantity"}, {"table.Product", "Product"}}),
#"Reordered Columns" = Table.ReorderColumns(#"Renamed Columns1",{"City", "table.Date", "Product", "Product Name", "Quantity"}),
#"Renamed Columns2" = Table.RenameColumns(#"Reordered Columns",{{"table.Date", "Date"}})
in
#"Renamed Columns2"
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Best Regards,
Dedmon Dai
you can use a Union() function. Create a new table like this
newTable =
var t1 = summarize(oldTable, oldTable[City], oldTable[Date], oldTable[Product1], oldTable[Quantity1])
var t2 = summarize(oldTable, oldTable[City], oldTable[Date], oldTable[Product2], oldTable[Quantity2])
var t3 = summarize(oldTable, oldTable[City], oldTable[Date], oldTable[Product3], oldTable[Quantity3])
return filter(union(t0,t1, t2, t3), [date]<> blank())
or something like that
Try the Power Query solution below. The concept is as follows:
1. Merge each pair of columns (Product 1 and Quantity 1, Product 2 and Quantity 2, etc.) using a delimiter.
2. Unpivot the merged columns.
3. Split the Value column by the delimiter.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcknMyUksVtJRstQ3NARS4fn5KUDKxBTEzkhNLAHSxkZAwr8oFUgaGSrF6kQrOZYWl2TmQXQhJI2RDDAyABIgBFLukQ9Unw9Vb4xksokRQoehOUxHLAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [City = _t, Date = _t, Product1 = _t, Quantity1 = _t, Product2 = _t, Quantity2 = _t, Product3 = _t, Quantity3 = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"City", type text}, {"Date", type date}, {"Product1", type text}, {"Quantity1", Int64.Type}, {"Product2", type text}, {"Quantity2", Int64.Type}, {"Product3", type text}, {"Quantity3", Int64.Type}}),
#"Merged Columns" = Table.CombineColumns(Table.TransformColumnTypes(#"Changed Type", {{"Quantity1", type text}}, "en-US"),{"Product1", "Quantity1"},Combiner.CombineTextByDelimiter(",", QuoteStyle.None),"1"),
#"Merged Columns1" = Table.CombineColumns(Table.TransformColumnTypes(#"Merged Columns", {{"Quantity2", type text}}, "en-US"),{"Product2", "Quantity2"},Combiner.CombineTextByDelimiter(",", QuoteStyle.None),"2"),
#"Merged Columns2" = Table.CombineColumns(Table.TransformColumnTypes(#"Merged Columns1", {{"Quantity3", type text}}, "en-US"),{"Product3", "Quantity3"},Combiner.CombineTextByDelimiter(",", QuoteStyle.None),"3"),
#"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Merged Columns2", {"City", "Date"}, "Attribute", "Value"),
#"Split Column by Delimiter" = Table.SplitColumn(#"Unpivoted Other Columns", "Value", Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv), {"Value.1", "Value.2"}),
#"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Value.1", type text}, {"Value.2", Int64.Type}}),
#"Renamed Columns" = Table.RenameColumns(#"Changed Type1",{{"Attribute", "Product"}, {"Value.1", "Product Name"}, {"Value.2", "Quantity"}}),
#"Filtered Rows" = Table.SelectRows(#"Renamed Columns", each ([Product Name] <> ""))
in
#"Filtered Rows"
This link explains it in detail:
https://datachant.com/2019/10/11/guest-story-unpivot-pairs-of-columns/
Proud to be a Super User!
Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes!
Check out the October 2025 Power BI update to learn about new features.