Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!Calling all Data Engineers! Fabric Data Engineer (Exam DP-700) live sessions are back! Starting October 16th. Sign up.
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_newTable | Table1 | Table2 |
001 | Yes | Yes |
002 | Yes | Yes |
003 | Yes | No |
008 | No | Yes |
Can someone help me, please?
Solved! Go to Solution.
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
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
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