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
scabral
Helper IV
Helper IV

RANK within group when filtering

Hi,

 

I have the following data table in Power BI with a sequence by acct with highes value to lowest value:

 

AcctLocationKeyValueTypeSeq
1AAB300PH1
1AAC550HE2
1AAD700PH3
1AAE788HE4
1AAF980PH5
2BBA450HE1
2BBB480PH2
2BBC700PH3

 

If i place the data in a table in Power BI and filter by Type = "PH", i get this:

 

AcctLocationKeyValueTypeSeq
1AAB300PH1
1AAD700PH3
1AAF980PH5
2BBB480PH2
2BBC700PH3

 

What I want is a new measure that will re-rank the sequence based on the filter like this:

 

AcctLocationKeyValueTypeSeq
1AAB300PH1
1AAD700PH2
1AAF980PH3
2BBB480PH1
2BBC700PH2

 

thanks

Scott

1 ACCEPTED SOLUTION
tamerj1
Super User
Super User

Hi @scabral 
Please refer to attached file with the solution

1.png

Rank = 
IF (
    HASONEVALUE ( 'Table'[LocationKey] ),
    RANKX ( 
        CALCULATETABLE ( 
            VALUES ( 'Table'[LocationKey] ), 
            ALLEXCEPT ( 'Table', 'Table'[Acct], 'Table'[Type] ) 
        ),
        CALCULATE ( 
            SUM ( 'Table'[Value] ), 
            ALLEXCEPT ( 'Table', 'Table'[LocationKey] ) 
        ),,
        ASC,
        Dense
    )
)

 

View solution in original post

3 REPLIES 3
CNENFRNL
Community Champion
Community Champion

CNENFRNL_0-1670138305231.png


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!

ppm1
Solution Sage
Solution Sage

Please also try this measure expression, that should also work when there is no external filter on Type (i.e., match your original sequence #s).

Acct Rank =
RANKX (
    CALCULATETABLE (
        SUMMARIZE ( T5, T5[Type], T5[LocationKey] ),
        ALLSELECTED ( t5 ),
        VALUES ( T5[Acct] )
    ),
    CALCULATE ( SUM ( T5[Value] ) ),
    ,
    ASC
)

Pat

Microsoft Employee
tamerj1
Super User
Super User

Hi @scabral 
Please refer to attached file with the solution

1.png

Rank = 
IF (
    HASONEVALUE ( 'Table'[LocationKey] ),
    RANKX ( 
        CALCULATETABLE ( 
            VALUES ( 'Table'[LocationKey] ), 
            ALLEXCEPT ( 'Table', 'Table'[Acct], 'Table'[Type] ) 
        ),
        CALCULATE ( 
            SUM ( 'Table'[Value] ), 
            ALLEXCEPT ( 'Table', 'Table'[LocationKey] ) 
        ),,
        ASC,
        Dense
    )
)

 

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