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

Be one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now

Reply
Ramachandran
Helper III
Helper III

Rankx - Country and State level is not working

Hi,

I'm trying to get calculate the 3 largest state excluding the “Other States” dimension member, based on Sum of sales amount.  Then, calculate the top2 country for those 3 state again based on "Sum of Sales Amount".
So, what I did, I created Rank measure
Rank Country & State =
IF (
ISINSCOPE ( 'Sample'[State]),
if(LEFT(MIN('Sample'[State]), 6 )= "Other ", 0,
RANKX (
CALCULATETABLE (
VALUES ( 'Sample'[State] ),
ALLSELECTED ( 'Sample'[State])
),
[Sum of State Amount]
)
)
,
IF (
ISINSCOPE ( 'Sample'[Country]),
VAR CategorySales = [Sum of State Amount]
RETURN
CALCULATE (
RANKX (
VALUES ( 'Sample'[Country]),
[Sum of State Amount],
CategorySales
),
ALLSELECTED ()
)
)
)
but ranking measure is not fetching correct value. 
current output,

Ramachandran_0-1653900960850.png

I would expect output is below,

Ramachandran_1-1653901026991.png

Someone suggest me, how to I change the Ranking measure and get a solution.
For your information, Ranking calculation you dont use "Other States" dimension values that means exclude the Other States values. but you should show the report. 
The .pbix file available in https://drive.google.com/file/d/1pgrnS09XF9Lo419l8pTUUfpNYoNZkWaM/view?usp=drivesdk

thanks,

Ram

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

Hi @Ramachandran ,

I updated your sample pbix file(see attachment), please check whether that is what you want.

1. Update the measure [Rank-Country] and [Rank-State] as below

Rank-Country = 
VAR _selcountry =
    SELECTEDVALUE ( 'Sample'[Country] )
RETURN
    RANKX (
        ALLSELECTED ( 'Sample'[Country] ),
        SUMX ( ALLEXCEPT ( 'Sample', 'Sample'[Country] ), [Sum of State Amount] ),
        ,
        DESC,
        DENSE
    )
Rank-State = 
VAR _selcountry =
    SELECTEDVALUE ( 'Sample'[Country] )
VAR _selstate =
    SELECTEDVALUE ( 'Sample'[State] )
RETURN
    IF (
        _selstate = "Other States",
        BLANK (),
        RANKX (
            FILTER (
                ALLSELECTED ( 'Sample' ),
                'Sample'[Country] = _selcountry
                    && 'Sample'[State] <> "Other States"
            ),
            'Sample'[Sum of State Amount],
            ,
            DESC,
            DENSE
        )
    )

2. Apply a visual level filter on the matrix with the conditions:  [Rank-Country]<=2 and [Rank-State] <=3

yingyinr_0-1654158488831.png

Best Regards

Community Support Team _ Rena
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-yiruan-msft
Community Support
Community Support

Hi @Ramachandran ,

I updated your sample pbix file(see attachment), please check whether that is what you want.

1. Update the measure [Rank-Country] and [Rank-State] as below

Rank-Country = 
VAR _selcountry =
    SELECTEDVALUE ( 'Sample'[Country] )
RETURN
    RANKX (
        ALLSELECTED ( 'Sample'[Country] ),
        SUMX ( ALLEXCEPT ( 'Sample', 'Sample'[Country] ), [Sum of State Amount] ),
        ,
        DESC,
        DENSE
    )
Rank-State = 
VAR _selcountry =
    SELECTEDVALUE ( 'Sample'[Country] )
VAR _selstate =
    SELECTEDVALUE ( 'Sample'[State] )
RETURN
    IF (
        _selstate = "Other States",
        BLANK (),
        RANKX (
            FILTER (
                ALLSELECTED ( 'Sample' ),
                'Sample'[Country] = _selcountry
                    && 'Sample'[State] <> "Other States"
            ),
            'Sample'[Sum of State Amount],
            ,
            DESC,
            DENSE
        )
    )

2. Apply a visual level filter on the matrix with the conditions:  [Rank-Country]<=2 and [Rank-State] <=3

yingyinr_0-1654158488831.png

Best Regards

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

@Ramachandran , Refer if my example in the video can help

IsInScope - Switch Rank at different levels - https://youtu.be/kh0gezKICEM

Join us as experts from around the world come together to shape the future of data and AI!
At the Microsoft Analytics Community Conference, global leaders and influential voices are stepping up to share their knowledge and help you master the latest in Microsoft Fabric, Copilot, and Purview.
️ November 12th-14th, 2024
 Online Event
Register Here

Hi Amit, I have watched your refered video's it will work to get rank both state and country level measures...
My screnario is state level exclude "Other states" dimension values.
how to exclude "Other States" dimension value and get state level ranking measure value
Rank-State = RANKX(ALLSELECTED('Sample'[State]), 'Sample'[Sum of State Amount], , DESC, Dense)
Rank-Country = RANKX(ALLSELECTED('Sample'[Country]), 'Sample'[Sum of State Amount], , DESC, Dense)
Rank Combine =
if(ISINSCOPE('Sample'[State]) , _MEASURES_[Rank-State], _MEASURES_[Rank-Country])

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.

ArunFabCon

Microsoft Fabric Community Conference 2025

Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.