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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
tbennett93
Frequent Visitor

Am I Using RANKX Incorrectly? It causes a cartesian join across relationships.

When I use RANKX, it seems to cause a cartesian join across a relationship.

 

Example:

FACTtable

ColourIdValue
16
22
37
42
51
54

 

DIMtable

ColourIDColour
1Red
2White
3Blue
4Orange
5Purple

 

Create a relationship between these on ColourID

 

Now create a RANKX measure:

rankcol = RANKX(all('FACTtable'),CALCULATE(SUM('FACTtable'[Value])))
 
Now in a Table visual, display the colour, value and ranking:
tbennett93_0-1670405034272.png

 

The ranking causes a strange cartesian join that we can see when we add the colour IDs from each respective table:

tbennett93_1-1670405078578.png

 

 

Now we can fix this by changing the RANK function to be:

rankcol = IF(HASONEVALUE(FACTtable[Value]),RANKX(all('FACTtable'),CALCULATE(SUM('FACTtable'[Value]))))
 
This essentially ignores any of the non-matching pairs in the cartesian join and allows the rank to work as expected:
tbennett93_3-1670405168107.png

 

 

My question is. Am I doing something wrong? It took a lot of research and digging to find the solution to this and it doesn't really feel intuitive. When I look at other people's example online, they don't seem to have this issue and there aren't that many posts about this issue online. I'd have thought the forums would be full of this type of issue.

 

Am I doing my RANKX wrong or does Power BI just expect us to use HASONEVALUE every time we use RANKX?

 

The function works fine on a single table if you merge your DIMs into your FACT but obviously this goes against all guidance, yet there is no explicit guidance on how to use RANKX properly in a Dimensional model.

1 ACCEPTED SOLUTION
CNENFRNL
Community Champion
Community Champion

Such a seemingly simple issue involves many intricacies under the hood. Even a seasoned DAX user might be incapable to wrap his head around it.

 

  1. It's NOT rankx() that causes the cartisian product but it's the fact the cartisian product already exists there and those "unreasonable" rows are "accidentally" made visible by your measure.
    Here's a simple way to prove its existence,
    CNENFRNL_0-1670443911258.png

    all rows can be made dissapear this way,

    CNENFRNL_1-1670444514758.png

     

  2. When you drag columns into a viz functions, they function independently as separate filters; a measure evaluates under the comprehensive effects of all these filters. As long as a measure evaluates any value other than BLANK(), the correspondent row shows.

  3. A reasonable measure can be authored this way
    CNENFRNL_2-1670445249541.png

  4. Rankx() is one of the most frequently used and also trickiest functions in DAX. Once you manage to master it, DAX is almost under full control.

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
v-yueyunzh-msft
Community Support
Community Support

Hi , @tbennett93 

According to your description, you want to show the table , like this:

vyueyunzhmsft_0-1670465625441.png

But when you put the field you need on the visual , it seems to occur the "crossjoin".

The dax you use for this need is right:

rankcol = RANKX(all('FACTtable'),CALCULATE(SUM('FACTtable'[Value])))

But for the ALL() function used , it clear the filter in  fact table. Internal,it also clear the filter of the Dim table, so when you put the 'DImTable'[Colour] field on the visual , it occur the "Crossjoin"!

If you just put the measure in the fact table , it works perfectly:

vyueyunzhmsft_1-1670465820622.png

So for this question, you can create another measure to show the color name :

Color Name = var _colorId = MAX('FACTtable'[ColourId])
var _t = FILTER('DIMtable','DIMtable'[ColourID] = _colorId)
return
MAXX(_t,[Colour])

Then in the end we can meet your need:

vyueyunzhmsft_2-1670465918514.png

 


 

Thank you for your time and sharing, and thank you for your support and understanding of PowerBI! 

 

Best Regards,

Aniya Zhang

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly

CNENFRNL
Community Champion
Community Champion

Such a seemingly simple issue involves many intricacies under the hood. Even a seasoned DAX user might be incapable to wrap his head around it.

 

  1. It's NOT rankx() that causes the cartisian product but it's the fact the cartisian product already exists there and those "unreasonable" rows are "accidentally" made visible by your measure.
    Here's a simple way to prove its existence,
    CNENFRNL_0-1670443911258.png

    all rows can be made dissapear this way,

    CNENFRNL_1-1670444514758.png

     

  2. When you drag columns into a viz functions, they function independently as separate filters; a measure evaluates under the comprehensive effects of all these filters. As long as a measure evaluates any value other than BLANK(), the correspondent row shows.

  3. A reasonable measure can be authored this way
    CNENFRNL_2-1670445249541.png

  4. Rankx() is one of the most frequently used and also trickiest functions in DAX. Once you manage to master it, DAX is almost under full control.

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
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

Find out what's new and trending in the Fabric Community.

Top Solution Authors