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

Enhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.

Reply
Iamnvt
Continued Contributor
Continued Contributor

Merge by Text Contain Any - Multiple values in a row

@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:

 

WordValue
A12
E22
D10
B5

 

Expected Merged result:

 

Column1Merged withResult
A, B, CA12
A, B, CB5
B, DB5
B, DD10
E, FE22
1 ACCEPTED SOLUTION
Nolock
Resident Rockstar
Resident Rockstar

(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

Capture.PNG

View solution in original post

2 REPLIES 2
Nolock
Resident Rockstar
Resident Rockstar

(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

Capture.PNG

Iamnvt
Continued Contributor
Continued Contributor

Truly mastery! Thank you very much.

Helpful resources

Announcements
July 2025 community update carousel

Fabric Community Update - July 2025

Find out what's new and trending in the Fabric community.

July PBI25 Carousel

Power BI Monthly Update - July 2025

Check out the July 2025 Power BI update to learn about new features.