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!The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more
I would like to merge two tables without creating duplicates in first table. Second table has duplicated IDs, which is what I need.
For example, table 1:
ID Name
1 XX
2 YX
3 YY
Table 2:
ID Info
2 c
2 a
4 b
Currently it does
1 XX m
2 YX c
2 YX a
3 YY
What I want:
1 XX m
2 YX c a
3 YY
Solved! Go to Solution.
Hi, @Vampirtc
Based on your description, i created data to reproduce your scenario. The pbix file is attached in the end.
Table1:
Table2:
You may create a new query with the following m codes in 'Advanced Editor'.
let
Source = Table.NestedJoin(Table1, {"ID"}, Table2, {"ID"}, "Data", JoinKind.LeftOuter),
Custom1 = Table.TransformColumns(Source,{"Data",each Text.Combine([Info]," "),type text})
in
Custom1
Result:
Best Regards
Allan
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Thank you both that solved the problem.
Hi, @Vampirtc
Based on your description, i created data to reproduce your scenario. The pbix file is attached in the end.
Table1:
Table2:
You may create a new query with the following m codes in 'Advanced Editor'.
let
Source = Table.NestedJoin(Table1, {"ID"}, Table2, {"ID"}, "Data", JoinKind.LeftOuter),
Custom1 = Table.TransformColumns(Source,{"Data",each Text.Combine([Info]," "),type text})
in
Custom1
Result:
Best Regards
Allan
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hello @Vampirtc
the trick here is to no use Table.ExpandTableColumn but use Table.AggregateTableColumn and as a function use Text.Combine.
Table.AggregateTableColumn(Join, "TableB", {{"Info",each Text.Combine(_, " ") , "Info aggregated"}})
Here the complete code
let
TableA = let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUXJ0VIrViVYyAjKdnMBMYyDT2VkpNhYA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Name = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"Name", type text}})
in
#"Changed Type",
TableB = let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUUpUitWBsJLALCMgKxnOSgGzjIGsVDgrTSk2FgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Info = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"Info", type text}})
in
#"Changed Type",
Join = Table.NestedJoin
(
TableA,
"ID",
TableB,
"ID",
"TableB",
JoinKind.LeftOuter
),
#"Aggregated TableB" = Table.AggregateTableColumn(Join, "TableB", {{"Info",each Text.Combine(_, " ") , "Info aggregated"}})
in
#"Aggregated TableB"
this is the output
Copy paste this code to the advanced editor in a new blank query to see how the solution works.
If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too
Have fun
Jimmy
The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!
| User | Count |
|---|---|
| 19 | |
| 10 | |
| 9 | |
| 8 | |
| 7 |