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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Wahid777
Frequent Visitor

Creating a conditional column with boolean (Yes/No) result for matching partial text matches

Hi

 

I've got a column listed as below and I'm trying to create a new column (with a Yes/No or True/False response) if some matches of certain keywords are found in the original column. Would "CONTAINS" be useful here? or should I create a new column with my Keywords [CEO, Chief Executive, Officer, CFO, Chief Financial Officer, Ambassador] and use Search?

 

Original columnNew conditional column
Mr John is the CEO of xYes
Ms Lynn is the Vice president of YNo
Tom is the ambassador of USA to the UKYes
Jerry is the Company Secretary of X IncNo

 

Keywords
Ambassador
CEO
Chief Executive Officer
Chief Financial Officer
CFO
1 ACCEPTED SOLUTION
v-alq-msft
Community Support
Community Support

Hi, @Wahid777 

 

Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.

Table1:

a1.png

 

Table2:

a2.png

 

You may create a custom column with the following codes.

if List.ContainsAny(Text.Split([Original column]," "),Table2[Keywords],Comparer.OrdinalIgnoreCase)
then "Yes" else "No"

 

Result:

a3.png

 

Best Regards

Allan

 

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

4 REPLIES 4
v-alq-msft
Community Support
Community Support

Hi, @Wahid777 

 

Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.

Table1:

a1.png

 

Table2:

a2.png

 

You may create a custom column with the following codes.

if List.ContainsAny(Text.Split([Original column]," "),Table2[Keywords],Comparer.OrdinalIgnoreCase)
then "Yes" else "No"

 

Result:

a3.png

 

Best Regards

Allan

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Anonymous
Not applicable

you could get the info you want using the code used here

 

although no answer has been promoted to solution by @EmPi

 

you have just to change the labels, and get the additional information of what item matches, non only that there is one match:

 

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcvR1jPL3UwhwjPR19QsJVnANDfIPcFUI1nPWc9RTcHFVitUBKvJx8VRw93XyUNBWcPbXU/B2Bwunlhblp2WWGJkouOcmeYCF8lLLFYpL8otSwbwAf2d/BdfMvKLM5IyS0rz04tzE1KLsklSo+lgA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [#"Bank transfer intended purpose" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Bank transfer intended purpose", type text}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Category", each Text.Combine(List.Transform(Text.SplitAny([#"Bank transfer intended purpose"], Text.Combine(List.Difference({" ".."@"},{"0".."9"}))), each Record.FieldOrDefault(storeDict, Text.Lower(_))),";"))
in
    #"Added Custom"

 

 

 

let
    dict = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcsxNrMrPU9JRcivNU4rVAQrkpGSCuPn5KQrBJflFqWBR15TU7ERM4YD85Hyw3qK8zJJSmNrSovy0zBIjE6CMe2WuUmwsAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Store = _t, Category = _t]),
    #"Changed Type" = Table.TransformColumnTypes(dict,{{"Store", type text}, {"Category", type text}})
in
 Record.FromList(dict[Store],List.Transform(dict[Store],Text.Lower))

 

 

 

Jimmy801
Community Champion
Community Champion

Hello @Wahid777 

 

you can use a combination of List.Transform, List.AnyTrue and Text.Contains. Here the example

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("Pc0xDsIwEETRq4xccwmEKAggihAEilwYZ1Fc2BvtusC3x7FE6vdHM47mKuh4TgiKPBMOxxv4g6+xu2qKS0mbPYInLEIaJkp5zV4tu3P8Jy6+naqbWFYe+j0yNxjOLe1IpGxfHBeXCnryQtlVqJsnTskba38=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Original column" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Original column", type text}}),
    CheckWords = Table.AddColumn
    (
        #"Changed Type",
        "Check",
        (add)=> List.AnyTrue(List.Transform({"Ambassador","CEO","Chief Executive Officer","Chief Financial Officer","CFO"}, each Text.Contains(Text.Upper(add[Original column]), Text.Upper(_))))
    )
in
    CheckWords

 

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

CNENFRNL
Community Champion
Community Champion

Hi, there, I use to List.Intersect as follows,

let
    Source = #table({"Original column"}, {{"Mr John is the CEO of x"},{"Ms Lynn is the Vice president of Y"},{"Tom is the ambassador of USA to the UK"},{"Jerry is the Company Secretary of X Inc"}}),
    Keywords = #table({"Keywords"}, {{"Ambassador"}, {"CEO"}, {"Chief Executive Officer"}, {"Chief Financial Officer"}, {"CFO"}}),
    #"Added Custom" = Table.AddColumn(Source, "Custom", each 
        [counter = List.Count(List.Intersect({Text.Split(_[Original column], " "), Keywords[Keywords]}, Comparer.OrdinalIgnoreCase)),
        result = if counter > 0 then "YES" else "NO"][result]
    )
in
    #"Added Custom"

Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors
Top Kudoed Authors