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

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
AntrikshSharma
Community Champion
Community Champion

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

 

 

View solution in original post

4 REPLIES 4
AntrikshSharma
Community Champion
Community Champion

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

 

 

Anonymous
Not applicable

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

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

Mariusz
Community Champion
Community Champion

Hi @Anonymous 

 

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

 

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.