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

Calling all Data Engineers! Fabric Data Engineer (Exam DP-700) live sessions are back! Starting October 16th. Sign up.

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

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

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
FabCon Global Hackathon Carousel

FabCon Global Hackathon

Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Top Solution Authors
Top Kudoed Authors