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
artjomsf
Frequent Visitor

Dynamically rank and group rows to show top-3 vs other

Hi all,

 

I have a table with data with sales per client per month, something simple like this:

artjomsf_0-1661350707507.png

Where I can achive ranking with RANKX.

 

Next I need: for each month to determine top-3 clients by "Amount" and compare see how much of total they do have, i.e. steps would be:

  • Rank clients
  • Sum top-3, sum all others
  • Get relative value in %

artjomsf_1-1661350811941.png

In the end Im looking for output like this:

artjomsf_2-1661350904530.png

 

So far I could do just RANKX ranking that does work with clients and months:

 ClientRank = RANKX (ALL(clients[Client]), calculate(sum(clients[amount])))

 but now I am struggling with having them aggregated in two groups. Is there a way to achieve that?

Thanks!

1 ACCEPTED SOLUTION
Greg_Deckler
Super User
Super User

@artjomsf Create a disconnected table using an Enter Data query that contains 2 rows. Top 3 and Others

Construct a measure like:

 

Measure =
  VAR __Category = MAX('DisconnectedTable'[Value])
  VAR __Table = ADDCOLUMNS(SUMMARIZE('clients',[Client],[Month],"amount",[amount]),"rank",[ClientRank])
  VAR __Top3 = FILTER(__Table,[rank]<=3)
  VAR __Others = FILTER(__Table,[rank]>3)
  VAR __Amount = IF(__Category = "Top-3",SUMX(__Top3,[amount]),SUMX(__Others,[amount]))
RETURN
  __Amount

 


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

View solution in original post

4 REPLIES 4
Greg_Deckler
Super User
Super User

@artjomsf Create a disconnected table using an Enter Data query that contains 2 rows. Top 3 and Others

Construct a measure like:

 

Measure =
  VAR __Category = MAX('DisconnectedTable'[Value])
  VAR __Table = ADDCOLUMNS(SUMMARIZE('clients',[Client],[Month],"amount",[amount]),"rank",[ClientRank])
  VAR __Top3 = FILTER(__Table,[rank]<=3)
  VAR __Others = FILTER(__Table,[rank]>3)
  VAR __Amount = IF(__Category = "Top-3",SUMX(__Top3,[amount]),SUMX(__Others,[amount]))
RETURN
  __Amount

 


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

@Greg_Deckler 

thanks a lot! That worked like charm! Just one more thing:

I have reworked that to match yearly instead of monthly data (which does not really matter), but I have calculation of total not right:

artjomsf_0-1661359119853.png

It shows Grand Total same as "Top-3" total. Could there be a solution to that?

 

@artjomsf Ah yes, Measure Totals. This looks like a measure totals problem. Very common. See my post about it here: https://community.powerbi.com/t5/DAX-Commands-and-Tips/Dealing-with-Measure-Totals/td-p/63376

Also, this Quick Measure, Measure Totals, The Final Word should get you what you need:
https://community.powerbi.com/t5/Quick-Measures-Gallery/Measure-Totals-The-Final-Word/m-p/547907


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

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.