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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
thampton
Helper III
Helper III

Rank accounting for 0

I am using RANKX to display a rank based on a value. The value can either be positive or negative, but there will be some with no value (which will show zero). I would like to be able to rank based on highest to lowest, then putting all the blank/0's at the end. 

 

Current:

Value      Rank

5                          1

2                          2

0 (BLANK)            3

-1                         4

-2                         5

 

Desired Outcome

5                           1

2                           2

-1                          3

-2                          4

0 (BLANK)              5

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

Hi @thampton ,

 

We can create a measure using following formula to meet your requirement:

 

Rank = 
VAR t =
    FILTER ( ALLSELECTED ( 'Table' ), [Value] + 0 <> 0 )
RETURN
    IF (
        MAX ( 'Table'[Value] ) + 0 <> 0,
        RANKX ( t, CALCULATE ( MAX ( 'Table'[Value] ) ),, DESC ),
        CALCULATE ( DISTINCTCOUNTNOBLANK ( 'Table'[Value] ), t ) + 1
    )

4.PNG

 

We can also create a calculate column using following formula

 

RankColumn = 
VAR t =
    FILTER ( 'Table' , [Value] + 0 <> 0 )
RETURN
    IF (
        [Value] + 0 <> 0,
        RANKX ( t, [Value],, DESC ),
        CALCULATE ( DISTINCTCOUNTNOBLANK ( 'Table'[Value] ), t ) + 1
    )

 

5.PNG

 

5.PNG

 


BTW, pbix as attached.

 

Best regards,

Community Support Team _ Dong Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Community Support Team _ Dong Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

3 REPLIES 3
v-lid-msft
Community Support
Community Support

Hi @thampton ,


How about the result after you follow the suggestions mentioned in my original post?Could you please provide more details about it If it doesn't meet your requirement?

 

Best regards,

Community Support Team _ Dong Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Community Support Team _ Dong Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
v-lid-msft
Community Support
Community Support

Hi @thampton ,

 

We can create a measure using following formula to meet your requirement:

 

Rank = 
VAR t =
    FILTER ( ALLSELECTED ( 'Table' ), [Value] + 0 <> 0 )
RETURN
    IF (
        MAX ( 'Table'[Value] ) + 0 <> 0,
        RANKX ( t, CALCULATE ( MAX ( 'Table'[Value] ) ),, DESC ),
        CALCULATE ( DISTINCTCOUNTNOBLANK ( 'Table'[Value] ), t ) + 1
    )

4.PNG

 

We can also create a calculate column using following formula

 

RankColumn = 
VAR t =
    FILTER ( 'Table' , [Value] + 0 <> 0 )
RETURN
    IF (
        [Value] + 0 <> 0,
        RANKX ( t, [Value],, DESC ),
        CALCULATE ( DISTINCTCOUNTNOBLANK ( 'Table'[Value] ), t ) + 1
    )

 

5.PNG

 

5.PNG

 


BTW, pbix as attached.

 

Best regards,

Community Support Team _ Dong Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Community Support Team _ Dong Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
smpa01
Super User
Super User

Hello @thampton  not sure how did you want to solve this problem. Were you hoping to have a solution through a table, measure or calculated column?

I have done it by doing a table and measure

 

Soucre Data

Column1

5
2
0
-1
-2
 
 
0

 

Table

CALTBL = 
VAR _1 = FILTER(ALLNOBLANKROW('Table'[Column1]),'Table'[Column1]+0<>0)
VAR _2 = ADDCOLUMNS(_1,"Rank",RANKX(_1,[Column1]+0))
VAR _3 = MAXX(_2,[Rank])+1
VAR _4 = FILTER('Table','Table'[Column1]+0+1=1)
VAR _5 = ADDCOLUMNS(_4,"Rank",_3)
VAR _6 = UNION(_2,_5)
RETURN _6

Capture.PNG

 

Through a measure

Measure: = 
VAR _11 = RANKX(FILTER(ALLNOBLANKROW('Table'[Column1]),'Table'[Column1]+0<>0),CALCULATE(SUM('Table'[Column1])),,DESC)
VAR _1 = FILTER(ALLNOBLANKROW('Table'[Column1]),'Table'[Column1]+0<>0)
VAR _2 = ADDCOLUMNS(_1,"Rank",RANKX(_1,[Column1]+0))
VAR _3 = MAXX(_2,[Rank])+1
VAR _14 =SUM('Table'[Column1])
VAR _15 = IF(ISBLANK(_14)=True||_14=0,_3,_11)
RETURN _15

Capture.PNG

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

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors