Microsoft Fabric Community Conference 2025, March 31 - April 2, Las Vegas, Nevada. Use code FABINSIDER for a $400 discount.
Register nowGet inspired! Check out the entries from the Power BI DataViz World Championships preliminary rounds and give kudos to your favorites. View the vizzies.
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
Solved! Go to Solution.
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 )
Pbix as attached.
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 )
Pbix as attached.
I suggest to add a column in Table1 to separate the keyword from the text column, like:
newColumn =
@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.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code FABINSIDER for a $400 discount!
Check out the February 2025 Power BI update to learn about new features.
User | Count |
---|---|
85 | |
70 | |
68 | |
51 | |
32 |
User | Count |
---|---|
115 | |
100 | |
74 | |
65 | |
40 |