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

Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started

Reply
tbucki1
Advocate I
Advocate I

Need DAX Rank Fomula to ignore dimension values that are NULL

I am trying to write a DAX Rank measure however the rank formula works even when there is no value in my Name (Dimension) column. I need the Rank Formula to ignore null name values... I tried filtering the pivot table (Uncheck blanks), however the rank numbers stay the same. What and I doing wrong....? Here is my sample data...

 

I have two tables, One Dimension table with car names and ID...second table is my fact table with Car ID and sales amount... Lots of rows in here... over 200K. In the data model, ID from Car_Names Joins to the ID column in the Sales_Table. One to Many....

 

I have a DAX measure for Sales $: Sales Amount =: Sum('Sales_Table'[Sales])

I need a DAX Rank formula that omits a rank value when null names are in pivot. What am I suppose to do for this?

 

Table Name = Car_Names

Name           ID

Ford101
Honda102
GMC103
Mercedes104
Toyota105
Lexus106
Infinity107

 

 

Table Name = Sales_Table

ID           Sales

101$28,345
103$30,456
104$12,543
999$45,623
994$93,456
992$23,457
107$23,419
107$83,647
106$12,654
103$39,571

 

Below is a simple pivot Table I built with a RankX formula. Sales Amount is the DAX Measure listed from above...

***NOTE there are some IDs from the Sales_Tables that are not mapped into the Car_Names table so that is why there is a blank value for Names.... Most of the sales $ are unmapped to the DIM Car_Names table and have the highest rank value in the pivot so the Rank formula lables it a "1"... I need it to ignore this row and the $10.1M value...

 

Current pivot with Rank = Not Correct VIEW

 

NamesSales AmountRank
 $10,142,5761
Ford$6,364,1232
Honda$291,4358
GMC$3,872,5104
Mercedes$5,123,4713
Toyota$981,3425
Lexus$846,2356
Infinity$716,3327

 

This is what I want the results to look like.... Correct VIEW

NamesSales AmountRank
 $10,142,576 
Ford$6,364,1231
Honda$291,4357
GMC$3,872,5103
Mercedes$5,123,4712
Toyota$981,3424
Lexus$846,2355
Infinity$716,3326

 

I only want the Rank Measure to work on Mapped Text values from the Sales FACT Table.... not NULL Text Values....How would you write this?

1 ACCEPTED SOLUTION
v-shex-msft
Community Support
Community Support

HI @tbucki1,

You can use the below measure expression to get the rank of the amount that exclude the not matched records:

Measure =
VAR currName =
    SELECTEDVALUE ( T1[Name] )
VAR summary =
    FILTER (
        SUMMARIZE ( ALLSELECTED ( T2 ), [Name], [ID], "total", SUM ( T2[Amount] ) ),
        [Name] <> BLANK ()
    )
VAR ranked =
    ADDCOLUMNS ( summary, "Rank", RANKX ( summary, [total],, DESC ) )
RETURN
    MAXX ( FILTER ( ranked, [Name] = currName ), [Rank] )

7.png
Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.

View solution in original post

2 REPLIES 2
v-shex-msft
Community Support
Community Support

HI @tbucki1,

You can use the below measure expression to get the rank of the amount that exclude the not matched records:

Measure =
VAR currName =
    SELECTEDVALUE ( T1[Name] )
VAR summary =
    FILTER (
        SUMMARIZE ( ALLSELECTED ( T2 ), [Name], [ID], "total", SUM ( T2[Amount] ) ),
        [Name] <> BLANK ()
    )
VAR ranked =
    ADDCOLUMNS ( summary, "Rank", RANKX ( summary, [total],, DESC ) )
RETURN
    MAXX ( FILTER ( ranked, [Name] = currName ), [Rank] )

7.png
Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.
amitchandak
Super User
Super User

@tbucki1 , first you should try to address the problem. seem like one of the car name is there in sales not there in car_name. or there sales with balnk car name

create a measure like

calculate(Sum('Sales_Table'[Sales]), filter(care_name, not(isblank(car_name[name]))))

 

Use this measure in rank and try

Helpful resources

Announcements
Sept PBI Carousel

Power BI Monthly Update - September 2024

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

September Hackathon Carousel

Microsoft Fabric & AI Learning Hackathon

Learn from experts, get hands-on experience, and win awesome prizes.

Sept NL Carousel

Fabric Community Update - September 2024

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