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!Vote for your favorite vizzies from the Power BI Dataviz World Championship submissions. Vote now!
Hi there,
I thought it would be a simple matter but I have not found a solution despite a few hours spent on this.
I have a table that looks like the one below, just with many more rows and values:
Key Value
| A and B | 1 |
| A and B | 2 |
| C | 3 |
| D | 4 |
| E | 5 |
| X and Y | 6 |
| X and Y | 7 |
My desired output is as below:
Key Value
| A | 1 |
| B | 2 |
| C | 3 |
| D | 4 |
| E | 5 |
| X | 6 |
| Y | 7 |
After multiple tries of split, group, split into rows, adding index and split,... , remove duplicates, I always get the result below.
Key Value
| A | 1 |
| B | 1 |
| C | 3 |
| D | 4 |
| E | 5 |
| X | 6 |
| Y | 6 |
Would anyone be able to help me on this question?
Thanks in advance!
Solved! Go to Solution.
You can try something like the following.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclRIzEtRcFLSUTJUitVB5huB+c5AljGY5QJkmYBZrkCWKZgVAVYdCeSbofHNlWJjAQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Key = _t, Value = _t]),
#"Grouped Rows" = Table.Group(Source, {"Key"}, {{"AllRows", each _[Value], type table [Key=nullable text, Value=nullable text]}}),
#"Added Custom" = Table.AddColumn(#"Grouped Rows", "NewKey", each [Key], type text),
#"Split Column by Delimiter" = Table.ExpandListColumn(Table.TransformColumns(#"Added Custom", {{"NewKey", Splitter.SplitTextByDelimiter(" and ", QuoteStyle.Csv), let itemType = (type nullable text) meta [Serialized.Text = true] in type {itemType}}}), "NewKey"),
#"Added Custom1" = Table.AddColumn(#"Split Column by Delimiter", "Position", each [AllRows]{List.PositionOf(Text.Split([Key], " and "), [NewKey])}, type text),
#"Removed Columns" = Table.RemoveColumns(#"Added Custom1",{"Key", "AllRows"}),
#"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"NewKey", "Key"}, {"Position", "Value"}})
in
#"Renamed Columns"
From:
To:
Proud to be a Super User! | |
Hi @RitaHL,
Here's an M Code solution for your query. I'll leave the code used below. Thanks. Do ping back in case of any queries or confusion. Thanks!
Code:
let
Source = #table(
{"Key", "Value"},
{{"A and B", 1}, {"A and B", 2}, {"C", 3}, {"D", 4}, {"E", 5}, {"X and Y", 6}, {"X and Y", 7}}
),
List = List.Distinct(List.Combine(List.Transform(Source[Key], each Text.Split(_, "and")))),
Table = Table.TransformColumns(Table.AddIndexColumn(Source, "Keys", 0, 1), {"Keys", each List{_}})[
[Keys],
[Value]
]
in
Table
You can try something like the following.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclRIzEtRcFLSUTJUitVB5huB+c5AljGY5QJkmYBZrkCWKZgVAVYdCeSbofHNlWJjAQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Key = _t, Value = _t]),
#"Grouped Rows" = Table.Group(Source, {"Key"}, {{"AllRows", each _[Value], type table [Key=nullable text, Value=nullable text]}}),
#"Added Custom" = Table.AddColumn(#"Grouped Rows", "NewKey", each [Key], type text),
#"Split Column by Delimiter" = Table.ExpandListColumn(Table.TransformColumns(#"Added Custom", {{"NewKey", Splitter.SplitTextByDelimiter(" and ", QuoteStyle.Csv), let itemType = (type nullable text) meta [Serialized.Text = true] in type {itemType}}}), "NewKey"),
#"Added Custom1" = Table.AddColumn(#"Split Column by Delimiter", "Position", each [AllRows]{List.PositionOf(Text.Split([Key], " and "), [NewKey])}, type text),
#"Removed Columns" = Table.RemoveColumns(#"Added Custom1",{"Key", "AllRows"}),
#"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"NewKey", "Key"}, {"Position", "Value"}})
in
#"Renamed Columns"
From:
To:
Proud to be a Super User! | |
@RitaHL Question, why not:
A 1
A 2
B 1
B 2
C 3
D 4
...
Because that's pretty easy like so:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclRIzEtRcFLSUTJUitVB5huB+c5AljGY5QJkmYBZrkCWKZgVAVYdCeSbofHNlWJjAQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Key = _t, Value = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Key", type text}, {"Value", Int64.Type}}),
#"Split Column by Delimiter" = Table.SplitColumn(#"Changed Type", "Key", Splitter.SplitTextByDelimiter(" and ", QuoteStyle.Csv), {"Key.1", "Key.2"}),
#"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Key.1", type text}, {"Key.2", type text}}),
#"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Changed Type1", {"Value"}, "Attribute", "Value.1"),
#"Removed Columns" = Table.RemoveColumns(#"Unpivoted Columns",{"Attribute"})
in
#"Removed Columns"
Vote for your favorite vizzies from the Power BI World Championship submissions!
If you love stickers, then you will definitely want to check out our Community Sticker Challenge!
Check out the January 2026 Power BI update to learn about new features.
| User | Count |
|---|---|
| 7 | |
| 6 | |
| 4 | |
| 3 | |
| 3 |
| User | Count |
|---|---|
| 16 | |
| 12 | |
| 11 | |
| 7 | |
| 6 |