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

RANKX issue: dynamic index column with multiple filters

 

For dataset below, how can I create an index column or measure that indexes agents based on sum of their net sales, given year = 2019 and product = C without actually filtering any columns within Power Query?

 

I've read a lot of answers here but the solution either doesn't apply or won't work (eg. everything above 1500 is rank 1, 500 to 1000 is rank 2 etc.) so I would really appreciate your assistance. 

 

Thank you!

 

AgentSalesYearProduct
Sam10002019A
Sam2002017B
Sam3002019C
Emily30002019C
Karen10002018B
Karen2002019C

 

RankAgentSales
1Emily3000
2Sam300
3Karen200

 

1 ACCEPTED SOLUTION

It's very difficult to say without seeing your data but try this variation:

 

Rank4 = 
VAR __agent = MAX([Agent])
VAR __table = SUMMARIZE(ALL('Table19'),[Agent],"__sales",SUM([Sales]))
VAR __table2 = ADDCOLUMNS(__table,"__rank",RANKX(__table,[__sales],,DESC,Dense))
RETURN
MAXX(FILTER(__table2,[Agent]=__agent),[__rank])

@ 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

9 REPLIES 9
Greg_Deckler
Super User
Super User

If you do want it in DAX, then this should work:

 

Rank = 
VAR __year = MAX([Year])
VAR __product = MAX([Product])
RETURN
RANKX(FILTER(ALL('Table19'),[Year]=__year && [Product]=__product),[Sales],SUM([Sales]))

See Table19, Page 13


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

Hi Greg,


First of all thank you so much for always answering my questions 🙂 

 

I managed to create the index via measure below:

Rank = rankx(
ALLNOBLANKROW(Table[Agent]),
calculate(sum(Table[Sales])),,desc,dense)
 
However, if I try to show the region assigned to the agent, instead of ranking the agents by sales and also showing their regions, it ranks agents within the region. For example, 
AgentSalesYearProductRegion 
Sam10002019AWest
Sam2002017BWest
Sam3002019CWest
Emily30002019CEast
Karen10002018BWest
Karen2002019CWest
 
 becomes 
RankAgentSalesRegion
1Emily3000East
1Sam300West
2Karen200West

Is there any way to alter my formula as to disregard regions? 
 
Thank you in advance. 
 

OK, my original formula didn't have that issue, but I modified yours like this:

 

Rank2 = 
VAR __table = CALCULATETABLE('Table19',ALLEXCEPT('Table19','Table19'[Agent],'Table19'[Year],'Table19'[Product]),ALLNOBLANKROW('Table19'[Agent]))
RETURN
rankx(
__table,
calculate(sum(Table19[Sales])),,desc,dense)

See attached, Table19

 

 


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

I'm not sure why the formula isn't working, even without putting in region. 

It starts with the first 50 all being 1, and at the end goes to 20083 even though there are 283 rows in total. 

 

rank1.PNGrank2.PNG

It's very difficult to say without seeing your data but try this variation:

 

Rank4 = 
VAR __agent = MAX([Agent])
VAR __table = SUMMARIZE(ALL('Table19'),[Agent],"__sales",SUM([Sales]))
VAR __table2 = ADDCOLUMNS(__table,"__rank",RANKX(__table,[__sales],,DESC,Dense))
RETURN
MAXX(FILTER(__table2,[Agent]=__agent),[__rank])

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

I just added the filters in an ALLEXPECT and now it works perfectly - thank you so much!

Hooray! We got there!


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

I'm sorry, still doesn't work. The ranking isn't based on highest net sales (at least not the one after product & fiscal year filtered anyway).

Thank you for your time! I will keep looking 🙂 

Greg_Deckler
Super User
Super User

So you want a solution in Power Query? In DAX you would use RANKX. In Power Query you would ask for a lifeline from @ImkeF.


@ 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.