March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
table1
EID Month Does Exist (conditional col) Doesn't Exist(conditional col)
vanessa.escudero Jan 0 1
jayvee.valdez Jan 0 1
jayvee.valdez Nov 1 0
charlotte.yoro Feb 0 1
charlotte.yoro June 0 1
charlotte.yoro Nov 1 0
emma.solo March 0 1
andrea.baral June 0 1
andrea.baral Nov 1 0
table2
EID Month
jayvee.valdez Nov
charlotte.yoro Nov
andrea.baral Nov
Solved! Go to Solution.
Hi, @xRTP
Is this a error you encountered?
You need to make sure there are no duplicate records in table2.
You can also try formula like below:
Does Exist2 =
VAR result =
CALCULATE (
MAX ( table2[Index] ),
FILTER ( table2, table2[EID] = table1[EID] && table2[Month] = table1[Month] )
)
RETURN
IF ( ISBLANK ( result ), 0, 1 )
Doesn't Exist2 =
VAR result =
CALCULATE(MAX(table2[Index]),
FILTER(table2,table2[EID]=table1[EID]&&
table2[Month]=table1[Month]
))
RETURN
IF ( ISBLANK ( result ), 1, 0 )
Best Regards,
Community Support Team _ Eason
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi, @xRTP
You can add index column for each table in PowerQuery.
Then you can try calculated column like:
Does Exist =
VAR result =
LOOKUPVALUE (
table2[Index],
table2[EID], table1[EID],
table2[Month], table1[Month]
)
RETURN
IF ( ISBLANK ( result ), 0, 1 )
Doesn't Exist =
VAR result =
LOOKUPVALUE (
table2[Index],
table2[EID], table1[EID],
table2[Month], table1[Month]
)
RETURN
IF ( ISBLANK ( result ), 1, 0 )
Best Regards,
Community Support Team _ Eason
Hello, i've tried this but its giving me an error "A table of multiple values was supplied where a single value was expected."
Hi, @xRTP
Is this a error you encountered?
You need to make sure there are no duplicate records in table2.
You can also try formula like below:
Does Exist2 =
VAR result =
CALCULATE (
MAX ( table2[Index] ),
FILTER ( table2, table2[EID] = table1[EID] && table2[Month] = table1[Month] )
)
RETURN
IF ( ISBLANK ( result ), 0, 1 )
Doesn't Exist2 =
VAR result =
CALCULATE(MAX(table2[Index]),
FILTER(table2,table2[EID]=table1[EID]&&
table2[Month]=table1[Month]
))
RETURN
IF ( ISBLANK ( result ), 1, 0 )
Best Regards,
Community Support Team _ Eason
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
125 | |
84 | |
66 | |
54 | |
43 |
User | Count |
---|---|
203 | |
106 | |
98 | |
65 | |
56 |