Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.
@Nolock : this is the more general scenarios:
Table 1 have multiple values, separated by Comma, or blank, or any...
Column1 |
A, B, C |
B, D |
E, F |
Table 2: have many result values:
Word | Value |
A | 12 |
E | 22 |
D | 10 |
B | 5 |
Expected Merged result:
Column1 | Merged with | Result |
A, B, C | A | 12 |
A, B, C | B | 5 |
B, D | B | 5 |
B, D | D | 10 |
E, F | E | 22 |
Solved! Go to Solution.
(this post is a continuation of the post https://community.powerbi.com/t5/Power-Query/Merge-by-Text-Contain-Any/m-p/744975#M24766 where the initial requirements have been changed and it was recommended to open a new post).
Hi @Iamnvt,
I've prepared 2 tables and a PowerQuery query which combine these two tables.
TableWordValue with some sample data:
let Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTI0UorViVZyBTKNIEwXkKgBmOkEZJqCWQpAllJsLAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Word = _t, Value = _t]), #"Changed Type" = Table.TransformColumnTypes(Source,{{"Word", type text}, {"Value", Int64.Type}}) in #"Changed Type"
The solution:
let Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WctRRcNJRcFaK1YlWAjJcwAxXHQU3pdhYAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Column1 = _t]), // split text in Column1 into a list SplitList = Table.AddColumn(Source, "SplitList", each Text.Split([Column1], ", ")), // look up for every word in the table TableWordValue and get a record Word;Value back Lookup = Table.AddColumn( SplitList, "Lookup", (row) => List.Select( List.Transform(row[SplitList], (listItem) => Table.SelectRows(TableWordValue, each [Word] = listItem){0}?), each _ <> null ) ), // expand lists into rows ExpandList = Table.ExpandListColumn(Lookup, "Lookup"), // expand record into word and value ExpandResultRecord = Table.ExpandRecordColumn(ExpandList, "Lookup", {"Word", "Value"}) in ExpandResultRecord
(this post is a continuation of the post https://community.powerbi.com/t5/Power-Query/Merge-by-Text-Contain-Any/m-p/744975#M24766 where the initial requirements have been changed and it was recommended to open a new post).
Hi @Iamnvt,
I've prepared 2 tables and a PowerQuery query which combine these two tables.
TableWordValue with some sample data:
let Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTI0UorViVZyBTKNIEwXkKgBmOkEZJqCWQpAllJsLAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Word = _t, Value = _t]), #"Changed Type" = Table.TransformColumnTypes(Source,{{"Word", type text}, {"Value", Int64.Type}}) in #"Changed Type"
The solution:
let Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WctRRcNJRcFaK1YlWAjJcwAxXHQU3pdhYAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Column1 = _t]), // split text in Column1 into a list SplitList = Table.AddColumn(Source, "SplitList", each Text.Split([Column1], ", ")), // look up for every word in the table TableWordValue and get a record Word;Value back Lookup = Table.AddColumn( SplitList, "Lookup", (row) => List.Select( List.Transform(row[SplitList], (listItem) => Table.SelectRows(TableWordValue, each [Word] = listItem){0}?), each _ <> null ) ), // expand lists into rows ExpandList = Table.ExpandListColumn(Lookup, "Lookup"), // expand record into word and value ExpandResultRecord = Table.ExpandRecordColumn(ExpandList, "Lookup", {"Word", "Value"}) in ExpandResultRecord
Truly mastery! Thank you very much.
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
15 | |
11 | |
8 | |
8 | |
7 |
User | Count |
---|---|
15 | |
13 | |
9 | |
7 | |
6 |