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

Grow your Fabric skills and prepare for the DP-600 certification exam by completing the latest Microsoft Fabric challenge.

Reply
smpa01
Super User
Super User

DAX Left Anti Inactive Relationship

I have two tables called 'left' and 'right'

 

| left.colA | left.Val |
|-----------|----------|
| 1         | A        |
| 2         | B        |
| 4         | D        |
| 5         | E        |


| right.colA | right.colB |
|------------|------------|
| 1          | 3          |
| 2          | 4          |
| 3          | 5          |

 

They have one ACTIVE (left.colA-right.colA) and one INACTIVE (left.colA-right.colB) relationship.  

I want to perform a DAX query that generates what a LEFT ANTI join (FIlter 'left' such as it does not contain any value in left.colA that exists in right.colB) would produce on tbl[left] where the join columns are left.colA to right.colB.

 

So I want to end up with the following 

smpa01_0-1670991887861.png

 

Now, if I perform a join on ACTIVE relationship columns, I can take advantage of in-built ISEMPTY. But is there any way to utilize ISEMPTY if the joins are on INACTIVE relationship columns? I want to avoid COUNTROWS as I suspect it will be a lot slower on a large dataset [Ref-SQLBI]

smpa01_0-1670992573114.png

 

 

Table = 
var leftAntiActiveRelation = FILTER('left',NOT ISEMPTY(RELATEDTABLE('right')))
var rightAntiInActiveRelation = FILTER('left',CALCULATE(COUNTROWS('right'),USERELATIONSHIP('left'[left.colA],'right'[right.colB]))=0)
return rightAntiInActiveRelation

 

@AlexisOlson @CNENFRNL @OwenAuger 

Thank you in advance.

Sample pbix is attached

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs
1 ACCEPTED SOLUTION
CNENFRNL
Community Champion
Community Champion

Hi, @smpa01 , you always come up with tricky and interesting questiongs.

 

In theory, the expected result can be achieved this way,

CNENFRNL_0-1671044795267.png

 

But from perspective of modeling, such an anti-join is a typical violation of reference integrity

CNENFRNL_1-1671045116574.png

 


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

View solution in original post

2 REPLIES 2
AlexisOlson
Super User
Super User

You can also skip relationships entirely and use right.colA or right.colB the same way like this:

Table =
VAR _Right = VALUES ( 'right'[right.colB] )
RETURN
    FILTER ( 'left', NOT 'left'[left.colA] IN _Right )

I'm not sure about the efficiency of this though. This might be better since it doesn't have an iterator:

Table =
VAR _ColA =
    EXCEPT ( VALUES ( 'left'[left.colA] ), VALUES ( 'right'[right.colB] ) )
RETURN
    CALCULATETABLE ( 'left', TREATAS ( _ColA, 'left'[left.colA] ) )
CNENFRNL
Community Champion
Community Champion

Hi, @smpa01 , you always come up with tricky and interesting questiongs.

 

In theory, the expected result can be achieved this way,

CNENFRNL_0-1671044795267.png

 

But from perspective of modeling, such an anti-join is a typical violation of reference integrity

CNENFRNL_1-1671045116574.png

 


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

Helpful resources

Announcements
Europe Fabric Conference

Europe’s largest Microsoft Fabric Community Conference

Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.

RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.

MayPowerBICarousel1

Power BI Monthly Update - May 2024

Check out the May 2024 Power BI update to learn about new features.