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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
smpa01
Super User
Super User

Ranking issue

@AlexisOlson @CNENFRNL 

I  am trying to create Ranking by using SUBSTITUTEWITHINDEX .

It is working as desired in a table expression.

 

baseTable

| name   | row | cat  | rowCopy |
|--------|-----|------|---------|
| john   | 1   | cat2 | 1       |
| jane   | 2   | cat3 | 2       |
| joanne | 3   | cat1 | 3       |
| jenny  | 4   | cat4 | 4       |
| jones  | 5   | cat1 | 5       |
| jeff   | 6   | cat7 | 6       |

I want to generate a Ranking of a filtered table of the above (cat=cat1).

I want to achieve this

| name   | cat  | rowCopy | rank |
|--------|------|---------|------|
| joanne | cat1 | 3       | 0    |
| jones  | cat1 | 5       | 1    |

I can achieve the above with following
Table 2 =
VAR filt =
    FILTER ( 'Table', 'Table'[cat] = "cat1" )
VAR new2 =
    SUBSTITUTEWITHINDEX (
        'Table',
        "rank", SUMMARIZE ( filt, 'Table'[row] ),
        'Table'[row], 1
    )
RETURN
    new2

 

But it is not working in a Measure. Is it possible to make it work in a Measure?

The pbix is attached.

Thank you in advance.

 

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
2 ACCEPTED SOLUTIONS
Anonymous
Not applicable

Hi @smpa01 ,

I updated your sample pbix file(see the attachment), please check if that is what you want. You can create a measure as below to get the rank...

Measure = 
VAR tab =
    FILTER (
        ALLSELECTED ( 'wc' ),
        'wc'[Win] <> 0
            && 'wc'[Region] = SELECTEDVALUE ( 'wc'[Region] )
    )
VAR result =
    SUBSTITUTEWITHINDEX (
        'wc',
        "rank", SUMMARIZE ( tab, 'wc'[Win] ),
        'wc'[Win], DESC
    )
VAR _rank =
    MAXX ( result, [rank] )
RETURN
    IF ( ISBLANK ( _rank ), BLANK (), _rank + 1 )

yingyinr_0-1672381200057.png

In addition,  you can achieve the same requirement using RANKX function. Please create a measure as below to get it, it is easier...

Rank =
RANKX (
    FILTER ( ALLSELECTED ( 'wc' ), 'wc'[Region] = SELECTEDVALUE ( 'wc'[Region] ) ),
    CALCULATE ( SUM ( 'wc'[Win] ) ),
    ,
    DESC,
    DENSE
)

Best Regards

View solution in original post

This feels a bit for efficient since it's iterating over regions instead of every row:

Table 3 =
SELECTCOLUMNS (
    GENERATE (
        SUMMARIZE ( wc, wc[Region] ),
        VAR _Region = wc[Region]
        VAR _Partition_ =
            SELECTCOLUMNS ( FILTER ( wc, wc[Region] = _Region ), wc[Country], wc[Win] )
        VAR _AddCol_ =
            ADDCOLUMNS ( _Partition_, "@win", wc[Win] )
        VAR _SubIndex_ =
            SUBSTITUTEWITHINDEX (
                _AddCol_,
                "Rank", SUMMARIZE ( _AddCol_, [@win] ),
                [@win], DESC
            )
        RETURN
            _SubIndex_
    ),
    "Region", wc[Region],
    "Country", wc[Country],
    "Win", wc[Win],
    "Rank", [Rank] + 1
)

View solution in original post

9 REPLIES 9
CNENFRNL
Community Champion
Community Champion

It seems I've arrived a bit late. But frankly speaking, I've got no idea about SUBSTITUTEWITHINDEX(), I'll take a look at it.

 

Happy new year and enjoy DAX!


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!

Anonymous
Not applicable

Hi @smpa01 ,

Please update the formula of measure as below and you can get the desired result... You can find the details in the attachment.

Measure = 
VAR filt =
    FILTER ( ALLSELECTED ( 'Table' ), 'Table'[cat] = "cat1" )
VAR new2 =
    SUBSTITUTEWITHINDEX (
        'Table',
        "rank", SUMMARIZE ( filt, 'Table'[row] ),
        'Table'[row], 1
    )
RETURN
    MAXX ( new2, [rank] )

yingyinr_0-1672371961841.png

Best Regards

@Anonymous  many thanks !!! well done. 

Just wondering, if it is possible to achieve a ranking by a partition with SUBSTITUTEWITHINDEX 

E.g.

 

wc table

| Region        | Country   | Win |
|---------------|-----------|-----|
| South America | Brazil    | 5   |
| South America | Argentina | 3   |
| South America | Chile     | 0   |
| South America | Uruguay   | 2   |
| Europe        | Germany   | 4   |
| Europe        | Italy     | 4   |
| Europe        | Austria   | 0   |

end goal - Ranking of Win by Region Partition

| Region        | Country   | Win | Rank |
|---------------|-----------|-----|------|
| South America | Brazil    | 5   | 1    |
| South America | Argentina | 3   | 2    |
| South America | Uruguay   | 2   | 3    |
| Europe        | Germany   | 4   | 1    |
| Europe        | Italy     | 4   | 1    |

 

pbix is attached

 

@AlexisOlson @CNENFRNL 

 

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
Anonymous
Not applicable

Hi @smpa01 ,

I updated your sample pbix file(see the attachment), please check if that is what you want. You can create a measure as below to get the rank...

Measure = 
VAR tab =
    FILTER (
        ALLSELECTED ( 'wc' ),
        'wc'[Win] <> 0
            && 'wc'[Region] = SELECTEDVALUE ( 'wc'[Region] )
    )
VAR result =
    SUBSTITUTEWITHINDEX (
        'wc',
        "rank", SUMMARIZE ( tab, 'wc'[Win] ),
        'wc'[Win], DESC
    )
VAR _rank =
    MAXX ( result, [rank] )
RETURN
    IF ( ISBLANK ( _rank ), BLANK (), _rank + 1 )

yingyinr_0-1672381200057.png

In addition,  you can achieve the same requirement using RANKX function. Please create a measure as below to get it, it is easier...

Rank =
RANKX (
    FILTER ( ALLSELECTED ( 'wc' ), 'wc'[Region] = SELECTEDVALUE ( 'wc'[Region] ) ),
    CALCULATE ( SUM ( 'wc'[Win] ) ),
    ,
    DESC,
    DENSE
)

Best Regards

@Anonymous  follow up question.

In a pure table expression, how can I return a rank by partition.

For example, I can achieve this with RANKX as following

Table 4 =
ADDCOLUMNS (
    FILTER ( wc, wc[Win] <> 0 ),
    "rank", RANKX ( FILTER ( wc, wc[Region] = EARLIER ( wc[Region] ) ), wc[Win],, DESC )
)

smpa01_0-1672408311085.png

How can I do the same with SUBSTITUTEWITHINDEX in a pure table expression

I tried this

Table 3 =
VAR partitionFirst =
    CALCULATE ( MAX ( wc[Region] ) )
VAR base =
    FILTER ( ALL ( wc ), wc[Win] <> 0 && wc[Region] = partitionFirst )
VAR rankedTbl =
    SUBSTITUTEWITHINDEX (
        ADDCOLUMNS ( wc, "@win", wc[Win] ),
        "rank", SUMMARIZE ( base, [Win] ),
        wc[Win], DESC
    )
RETURN
    rankedTbl

but it did not work

smpa01_1-1672408872242.png

 

I know I can do this. But I am not looking for this.

smpa01_2-1672408906862.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

@smpa01 Here's how I'd modify your attempt:

Table 3 = 
VAR _NonZero_ = FILTER ( wc, wc[Win] <> 0 )
VAR _Ranked_ =
    ADDCOLUMNS (
        _NonZero_,
        "Rank",
            VAR _Region = wc[Region]
            VAR _Country = wc[Country]
            VAR _Partition_ = FILTER ( _NonZero_, wc[Region] = _Region )
            VAR _AddCol_ = ADDCOLUMNS ( _Partition_, "@win", wc[Win] )
            VAR _SubIndex_ = SUBSTITUTEWITHINDEX ( _AddCol_, "@Rank", SUMMARIZE ( _AddCol_, [@win] ), [@win], DESC )
            VAR _Row_ = FILTER ( _SubIndex_, wc[Country] = _Country )
            VAR _Rank = MAXX ( _Row_, [@Rank] ) + 1
            RETURN
                _Rank
    )
RETURN
    _Ranked_

This feels a bit for efficient since it's iterating over regions instead of every row:

Table 3 =
SELECTCOLUMNS (
    GENERATE (
        SUMMARIZE ( wc, wc[Region] ),
        VAR _Region = wc[Region]
        VAR _Partition_ =
            SELECTCOLUMNS ( FILTER ( wc, wc[Region] = _Region ), wc[Country], wc[Win] )
        VAR _AddCol_ =
            ADDCOLUMNS ( _Partition_, "@win", wc[Win] )
        VAR _SubIndex_ =
            SUBSTITUTEWITHINDEX (
                _AddCol_,
                "Rank", SUMMARIZE ( _AddCol_, [@win] ),
                [@win], DESC
            )
        RETURN
            _SubIndex_
    ),
    "Region", wc[Region],
    "Country", wc[Country],
    "Win", wc[Win],
    "Rank", [Rank] + 1
)

@AlexisOlson  this is simply Brilliant !!! Thank you again.

 

I rewrote the core query as below (for me to understand)

 

smpa01_0-1672436685025.png

 

Happy new year !!! @AlexisOlson @CNENFRNL 

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

@Anonymous  I know how to achieve the same with RANKX. I just wanted to see how can I do the same with a different DAX function

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
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.