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

Compare if a value is in another table and vice versa

Hello everyone,

 

I have two tables:
Table1

COD_1
001
002
003


Table2

COD_2
001
002
008


I would like to compare the COD column of Table1 with the COD column of Table2. Each value of these two columns is never repeated.
So I would like to create a third table that shows the CODs, and two columns named Table1 and Table2. Each of these columns informing whether the respective COD is in table 1 or table 2, or in both tables.
The table shoud be something like this:

COD_newTableTable1Table2
001YesYes
002YesYes
003YesNo
008NoYes


Can someone help me, please?

1 ACCEPTED SOLUTION
az38
Community Champion
Community Champion

Hi @Anonymous 

create a calculated table

Table = 
ADDCOLUMNS(
DISTINCT(
    UNION(
        SELECTCOLUMNS(Table1,"COD",Table1[COD_1]),
        SELECTCOLUMNS(Table2,"COD",Table2[COD_2])
    )
),
"Table1", IF(CALCULATE(COUNTROWS(Table1),Table1[COD_1]=EARLIER([COD])) > 0, "Yes", "No"),
"Table2", IF(CALCULATE(COUNTROWS(Table2),Table2[COD_2]=EARLIER([COD])) > 0, "Yes", "No")
)

then add put its fields to visual


do not hesitate to give a kudo to useful posts and mark solutions as solution
LinkedIn

View solution in original post

3 REPLIES 3
v-shex-msft
Community Support
Community Support

HI @Anonymous,

You can use union function to merge these records and use 'in' operator to check if they existed in specific table records:

Table =
SUMMARIZE (
    SELECTCOLUMNS ( UNION ( ALL ( T1[COD_1] ), ALL ( T2[COD_2] ) ), "COD", [COD_1] ),
    [COD],
    "T1", [COD] IN VALUES ( T1[COD_1] ),
    "T2", [COD] IN VALUES ( T2[COD_2] )
)

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.
vanessafvg
Super User
Super User

you can also do it in power query, see attached.





If I took the time to answer your question and I came up with a solution, please mark my post as a solution and /or give kudos freely for the effort 🙂 Thank you!

Proud to be a Super User!




az38
Community Champion
Community Champion

Hi @Anonymous 

create a calculated table

Table = 
ADDCOLUMNS(
DISTINCT(
    UNION(
        SELECTCOLUMNS(Table1,"COD",Table1[COD_1]),
        SELECTCOLUMNS(Table2,"COD",Table2[COD_2])
    )
),
"Table1", IF(CALCULATE(COUNTROWS(Table1),Table1[COD_1]=EARLIER([COD])) > 0, "Yes", "No"),
"Table2", IF(CALCULATE(COUNTROWS(Table2),Table2[COD_2]=EARLIER([COD])) > 0, "Yes", "No")
)

then add put its fields to visual


do not hesitate to give a kudo to useful posts and mark solutions as solution
LinkedIn

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.