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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Anonymous
Not applicable

Match column to lookup table column with longest match

Hello all,

I need help in making relatioship in data table and lookup table.

SAMPLE Data table:

LetterValue
a--1
aa---2
bbb-3
b---4
cc-5
cc---6

Note: Characters and "-" are for representation only to show that they differ from each other. It can be anything.

 

Lookup table:

Lookup LetterLookup Value
aa1
aaa2
aaaa3
bb1
bbb2
bbbb3
cc1
ccc2
cccc3

 

I need to match Letter column from table 1 to Letter lookup of lookup table. But structure is not same for these two. Thus, I need to match to that row of Lookup letter of Lookup table to match that has longest match to Letter column in Data Table.

 

Required result:

LetterValueLookup Value
a--1a1
aa---2a2
bbb-3b3
b---4b1
cc-5c2
cc---6c2

Can it be done using Power Query or DAX? Either a new column in data table OR a relation (between Letter and Lookup Letter columns) in model would work.

 

@amitchandak @AllisonKennedy @SteveCampbell

1 ACCEPTED SOLUTION

Hi @Anonymous ,

If the fields have the specific character like '-', '/' etc, you can spilit columns by these characters to extract the previous parts fields in the columns and merge them with the lookup table to expand the result.

You can refer this query:

Lookup table:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("LcqxDQAwCAPBXVzThIyDUgD77xDL0N1LH4GEIQ+ekbKvFVdRZM1Tsq8V8zTZ87TsawWf9wE=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Lookup Letter" = _t, #"Lookup Value" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Lookup Letter", type text}, {"Lookup Value", type text}})
in
    #"Changed Type"

Data table:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WStSvqACiCiUdJUOlWB2gAEgEKAQUMAILJCUlgXnGEJ5+BUKHCVgoORksbwrngOXMlGJjAQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Letter = _t, Value = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Letter", type text}, {"Value", Int64.Type}}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Changed Type", "Letter", Splitter.SplitTextByDelimiter("/", QuoteStyle.Csv), {"Letter.1", "Letter.2", "Letter.3", "Letter.4"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Letter.1", type text}, {"Letter.2", type text}, {"Letter.3", type text}, {"Letter.4", type text}}),
    #"Removed Columns" = Table.RemoveColumns(#"Changed Type1",{"Letter.2", "Letter.3", "Letter.4"}),
    #"Merged Queries" = Table.NestedJoin(#"Removed Columns", {"Letter.1"}, #"Lookup Table", {"Lookup Letter"}, "Lookup Table", JoinKind.LeftOuter),
    #"Expanded Lookup Table" = Table.ExpandTableColumn(#"Merged Queries", "Lookup Table", {"Lookup Value"}, {"Lookup Table.Lookup Value"})
in
    #"Expanded Lookup Table"

merge.png

 

Best Regards,
Community Support Team _ Yingjie Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

3 REPLIES 3
Jakinta
Solution Sage
Solution Sage

If I understood the logic properly this might be done without LookupTable. 

You are counting repeating characters at start of text string,correct?

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WStTVVdJRMlSK1QGygRwQzwjMS0pKAnGMIRyIjAmYk5wMYpvC2GAZM6XYWAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Letter = _t, Value = _t]),
    #"Added Custom" = Table.AddColumn(Source, "Lookup Value", each let t=[Letter] in Text.Combine({Text.Start(t,1),Text.From(List.Sum( List.Transform( {1.. Text.Length(t)}, each Number.From(List.Count(List.Distinct(Text.ToList(Text.Start(t,_))))=1))))},""))
in
    #"Added Custom"

 

Anonymous
Not applicable

Thank you for helping out.

Please excuse me for not being clear enough. The data is only for representation. "aa---" is actually something like "product/subproduct/version/modules"

Hi @Anonymous ,

If the fields have the specific character like '-', '/' etc, you can spilit columns by these characters to extract the previous parts fields in the columns and merge them with the lookup table to expand the result.

You can refer this query:

Lookup table:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("LcqxDQAwCAPBXVzThIyDUgD77xDL0N1LH4GEIQ+ekbKvFVdRZM1Tsq8V8zTZ87TsawWf9wE=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Lookup Letter" = _t, #"Lookup Value" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Lookup Letter", type text}, {"Lookup Value", type text}})
in
    #"Changed Type"

Data table:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WStSvqACiCiUdJUOlWB2gAEgEKAQUMAILJCUlgXnGEJ5+BUKHCVgoORksbwrngOXMlGJjAQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Letter = _t, Value = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Letter", type text}, {"Value", Int64.Type}}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Changed Type", "Letter", Splitter.SplitTextByDelimiter("/", QuoteStyle.Csv), {"Letter.1", "Letter.2", "Letter.3", "Letter.4"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Letter.1", type text}, {"Letter.2", type text}, {"Letter.3", type text}, {"Letter.4", type text}}),
    #"Removed Columns" = Table.RemoveColumns(#"Changed Type1",{"Letter.2", "Letter.3", "Letter.4"}),
    #"Merged Queries" = Table.NestedJoin(#"Removed Columns", {"Letter.1"}, #"Lookup Table", {"Lookup Letter"}, "Lookup Table", JoinKind.LeftOuter),
    #"Expanded Lookup Table" = Table.ExpandTableColumn(#"Merged Queries", "Lookup Table", {"Lookup Value"}, {"Lookup Table.Lookup Value"})
in
    #"Expanded Lookup Table"

merge.png

 

Best Regards,
Community Support Team _ Yingjie Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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

Top Solution Authors
Top Kudoed Authors