cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
Helper I
Helper I

How to output a text column based on a ranking measure and aggregate the values?

Hey,

Could someone please help me out with the following problem please?

 

If I have 5 animals for example with different values. I want to be able to rank the top three and then output the top 3 names and aggregte the remaining animals that didn't make it to the top 3. 

 

AnimalValueRank
Horses91
Chickens82
Frogs73
Dogs44
Cats15
   
Desired Output  
AnimalValue 
Horses9 
Chickens8 
Frogs7 
Other5 

 

I ranked using a measure:

RankTop3 =

Var RankAnimal = RANKX(ALLNOBLANKROW('Table'[Animal]),[Value],
,
DESC,
Dense
)
RETURN IF(RankAnimal <=3,[Value],BLANK())

However, this gives me the top 5 values when I put the column Animals and the measure RankTop3 together and not my desired output.

I was thinking I may need to use a calculated column as I need an IF statement that works with text but I don't know how to use it in conjunction with rank which is a measure.
 
Does anyone have any ideas?
 
Thank you in advance,
 
Lauren.
1 ACCEPTED SOLUTION

Accepted Solutions
Highlighted
Impactful Individual
Impactful Individual

Re: How to output a text column based on a ranking measure and aggregate the values?

Here is an example using Contoso dataset, but the idea is same. first create a rank column in your table based on the amount or anything.

ProductRank = 
RANKX (
    ALL ( Products[Brand] ),
    CALCULATE ( [Total Sales], ALLEXCEPT ( Products, Products[Brand] ) ),
    ,
    ASC
)

rank1.PNG 

Now we create a new column to group the brands based on the ranking

NewProductCategory = 
VAR ProductRank = Products[ProductRank]
VAR ProductBrand = Products[Brand]
VAR Result =
    IF ( ProductRank IN { 1, 2, 3 }, ProductBrand, "Others" )
RETURN
    Result

rank2.PNG

Now the final step is the put everything in a visualization

Total Sales = SUMX ( Sales, Sales[Quantity] * Sales[Net Price] )
Rank on Sales =
IF (
    HASONEVALUE ( Products[NewProductCategory] ),
    RANKX ( ALL ( Products[NewProductCategory] ), [Total Sales] )
)

rank3.PNG

 

 


Thank you,
Antriksh Sharma

View solution in original post

4 REPLIES 4
Highlighted
Super User IV
Super User IV

Re: How to output a text column based on a ranking measure and aggregate the values?

Hi @lauren1192 

 

Try this,

Top 3 and Others = 
IF(
    RANKX( 'Table', 'Table'[Value] ) <= 3,
    'Table'[Animal],
    "Others"
)

the rank formula will need to be adjusted if you have Animals duplicated in your table.

 
Best Regards,
Mariusz

If this post helps, then please consider Accepting it as the solution.

Please feel free to connect with me.
LinkedIn

 

Highlighted
Impactful Individual
Impactful Individual

Re: How to output a text column based on a ranking measure and aggregate the values?

Here is an example using Contoso dataset, but the idea is same. first create a rank column in your table based on the amount or anything.

ProductRank = 
RANKX (
    ALL ( Products[Brand] ),
    CALCULATE ( [Total Sales], ALLEXCEPT ( Products, Products[Brand] ) ),
    ,
    ASC
)

rank1.PNG 

Now we create a new column to group the brands based on the ranking

NewProductCategory = 
VAR ProductRank = Products[ProductRank]
VAR ProductBrand = Products[Brand]
VAR Result =
    IF ( ProductRank IN { 1, 2, 3 }, ProductBrand, "Others" )
RETURN
    Result

rank2.PNG

Now the final step is the put everything in a visualization

Total Sales = SUMX ( Sales, Sales[Quantity] * Sales[Net Price] )
Rank on Sales =
IF (
    HASONEVALUE ( Products[NewProductCategory] ),
    RANKX ( ALL ( Products[NewProductCategory] ), [Total Sales] )
)

rank3.PNG

 

 


Thank you,
Antriksh Sharma

View solution in original post

Highlighted
Helper I
Helper I

Re: How to output a text column based on a ranking measure and aggregate the values?

You are a legend! Very much appreciated, thank you. 🙂 

Highlighted
Impactful Individual
Impactful Individual

Re: How to output a text column based on a ranking measure and aggregate the values?

You're welcome, I am glad that I could help you. 🙂


Thank you,
Antriksh Sharma

Helpful resources

Announcements
August 2020 Community Challenge: Can You Solve These?

August 2020 Community Challenge: Can You Solve These?

We're excited to announce our first cross-community 'Can You Solve These?' challenge!

Super Users of the Quarter - Q2 2020

Super Users of the Quarter - Q2 2020

Who are our Super User Superstars? Who made it to the top of the leaderboards? Get the answers!

Community Blog

Community Blog

Visit our Community Blog for articles, guides, and information created by fellow community members.

Community Summit Australia – Join Online!

Community Summit Australia – Join Online!

Be a part of the leading Microsoft Business Applications digital event, curated for the APAC community.

Top Solution Authors