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
Anonymous
Not applicable

How do I use DAX to see if a field contains text in an unrelated table?

I have two unrelated tables where Table1 contains a list of items and Table2 contains a list of key terms. I want to check and see if each value in Table1 contains any value in Table 2.

 

Table1 is as follows:

Value

Snickers Bar

A-1 Gift Card

R-QAL Voucher

 

Table2 is as follows:

ID        Term

1        Snickers

2        Gift Card

3        Voucher

 

I want to return the Table2[ID] if the value in Table1[Value] contains a term in Table2. This is the desired result:

 

Value                        TermID

Snickers Bar                  1

A-1 Gift Card                2

R-QAL Voucher            3

1 ACCEPTED SOLUTION
v-frfei-msft
Community Support
Community Support

Hi @Anonymous ,

 

One sample for your reference. Please check the following steps as below.

 

1. Create a calculated table and insert a calculated column in it.

 

Table = CROSSJOIN(Table1,Table2)
Column = SEARCH('Table'[Term],'Table'[Value],,0)

2. Create another new calculated table to get the result.

 

RESULT =
CALCULATETABLE (
    SELECTCOLUMNS ( 'Table', "Value", 'Table'[Value], "TearmID", 'Table'[ID] ),
    'Table'[Column] <> 0
)

Capture.PNG

 

Pbix as attached.

 

Community Support Team _ Frank
If this post helps, then please consider Accept it as the solution to help the others find it more quickly.

View solution in original post

3 REPLIES 3
v-frfei-msft
Community Support
Community Support

Hi @Anonymous ,

 

One sample for your reference. Please check the following steps as below.

 

1. Create a calculated table and insert a calculated column in it.

 

Table = CROSSJOIN(Table1,Table2)
Column = SEARCH('Table'[Term],'Table'[Value],,0)

2. Create another new calculated table to get the result.

 

RESULT =
CALCULATETABLE (
    SELECTCOLUMNS ( 'Table', "Value", 'Table'[Value], "TearmID", 'Table'[ID] ),
    'Table'[Column] <> 0
)

Capture.PNG

 

Pbix as attached.

 

Community Support Team _ Frank
If this post helps, then please consider Accept it as the solution to help the others find it more quickly.
yelsherif
Resolver IV
Resolver IV

I suggest to add a column in Table1 to separate the keyword from the text column, like:

newColumn = 

switch(true,
FIND("Snickers",[Value])>0, "Snickers",
Find("Gift card",[Value])>0, "Gift card",
Find("Voucher",[Value])>0, "Voucher"
)

Then set a relationship between Table1 and Table2 on this newColumn and the Term

Finally you can create a table with Table1[Value] and Table2[ID]

@Anonymous you can add following column to get id

 

TermId = 
CALCULATE( MAX( TermTable[TermId] ), 
FILTER( TermTable, SEARCH( TermTable[Term], Table[Value], , -1 ) > 0 )
 )


Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

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.