Exclude some records from a SUMPRODUCT ranking formula

vegasbaby207

Board Regular
Joined
Nov 13, 2008
Messages
53
Hi,


I have a table of SalesReps with a two ranking formulas. The resulting rankings are used on dashboards on other worksheets. The formulas rank the performance of SalesReps within each RepGroup in ASC and DESC order (so that we can report on the top performing and bottom performing reps). The ranking is based on what percentage of their sales target they have achieved.


The problem occurs for new sales reps who don't have targets. Their "Achieved" value (Orders / Target) is undefined, corrected by formula to 0%. Because their achieved is 0%, they always top the bottom-performing sales reps, which is untrue for our purposes. We'd like to suppress the ranking of all reps with no target from the bottom performing ranking (or rank them last).


Here are the formulas I am using:


OrdersThisPeriod : SUMIFS formula referencing an external database
TargetThisPeriod : SUMIFS formula referencing an external database
Achieved : =IFERROR([@OrdersThisPeriod]/[@TargetThisPeriod],0)+(RAND()/100000) <---- I've added the random number to the formula so that I am almost guaranteed a unique Achieved percentage, which keeps my Rankings clean and unique.


RankingASC : =SUMPRODUCT(--([RepGroup]=[@RepGroup]),--([@Achieved]<[Achieved]))+1
RankingDESC : =SUMPRODUCT(--([RepGroup]=[@RepGroup]),--([@Achieved]>[Achieved]))+1


If required, I can upload a sheet with the table, but I would need to anonymise the data first which would take some time.


Thanks in advance.
 

Excel Facts

Enter current date or time
Ctrl+: enters current time. Ctrl+; enters current date. Use Ctrl+: Ctrl+; Enter for current date & time.
Could you adjust your IFERROR formula to insert 999,999.00 instead of zero and then adjust the SUMPRODUCT formulas to ignore 999,999.00 as follows:

RankingASC : =SUMPRODUCT(--([RepGroup]=[@RepGroup]),--([@Achieved]<[Achieved]), --([@Achieved]<>999,999))+1
RankingDESC : =SUMPRODUCT(--([RepGroup]=[@RepGroup]),--([@Achieved]>[Achieved]), --([@Achieved]<>999,999))+1

I haven't validated this with any data just trying to think it through.
 
Upvote 0
It's giving me a #VALUE ! result in the Ranking formulas. Note that I had to replace the <> with < because of the addition of the small random number to the IFERROR result. But that shouldn't matter, should it?
 
Upvote 0
I was able to get it to work with this formula and some test data.

=SUMPRODUCT((A1:A6="Red")*(B1:B6<>999999)*(B1:B6))+1

Result = 1.25


AB
1Blue.4
2Blue.3
3Red999999
4Red.25
5Green.3
6Green.2

<tbody>
</tbody>
 
Upvote 0
For your RankingsDESC try

=IF([@Achieved]<0.00001,"",SUMPRODUCT(--([RepGroup]=[@RepGroup]),--([@Achieved]>[Achieved]))+1-COUNTIFS([RepGroup],[@RepGroup],[Achieved],"<0.00001"))

.. or if you want/need to stick to SUMPRODUCT for it all, try

=IF([@Achieved]<0.00001,"",SUMPRODUCT(--([RepGroup]=[@RepGroup]),--([@Achieved]>[Achieved]))+1-SUMPRODUCT(--([RepGroup]=[@RepGroup]),--([Achieved]<0.00001)))
 
Last edited:
Upvote 0
Hi,

Thank you both for helping. Peter, I haven't tested yours as I was able to adapt Crystalyzer's post to suit my requirements.

I did the following:
1. added a new Achieved column to my table (Achieved2), using the 999999 method as suggested
2. added a new column called NoNewRankingDESC which used the identical formula to the RankingDESC field, except that it used Achieved2 instead of Achieved. I did not have to add the [Achieved]<>999999 parameter.

I'm happy to share a sample of my table with the new columns in case it is useful to someone, but i am not able to attach files. Let me know if you'd like it and I can share it some other way.

Thanks again.
 
Upvote 0
Peter, I haven't tested yours as I was able to adapt Crystalyzer's post to suit my requirements.
You are of course welcome to use whatever method you want, but why don't you give it a go anyway in a copy of your workbook since it doesn't require the extra column, just an adjustment to your current formula?
 
Last edited:
Upvote 0
Hi Peter,

I gave it a go, but it unfortunately doesn't work in cases where OrdersThisPeriod is 0 or under. So, if a sales rep has a target of $1000, but have achieved no sales (quite possible), or even -ve sales (also possible, especially early on in the season when customers return stock that they were over-sold the previous season, but that's a story for another day!)
 
Upvote 0
Hi Peter,

I gave it a go, but it unfortunately doesn't work in cases where OrdersThisPeriod is 0 or under.
We hadn't heard of that possibility before, but in any case, to help my understanding, I would be interested to know if are any of these RankingDESC incorrect and why? For example, should any/all of rows 7, 9 & 10 have a value rather than blank?

I have used your formula for Achieved and RankingsASC and mine for RankingsDESC.

Excel Workbook
ABCDEF
1RepGroupAchievedTargetThisPeriodOrdersThisPeriodRankingsASCRankingsDESC
2A1.3333413426812
3A0.8571505127621
4B3.02314E-06054
5A8.53403E-07035
6B0.50000077210531
7A-0.9999936665-56
8B1.078949663384113
9A2.1619E-06004
10A9.46406E-06503
11B0.900009305201822
Rank Excluding Some
 
Upvote 0
Hi Peter,
Based on your data, the following rows should have a value in RankingDESC (I've indicated the value in brackets):

Row10 (1)
This in turn will lead to ranking changes for Row3 (2) and Row2 (3)

To translate this into Business Logic, the salesperson represented by row 10 had a Sales Target of $5, and has achieved actual sales of $0. He is clearly a worse performing rep than the one in Row 3 who had a target of $7 and achieved $6.
 
Upvote 0

Forum statistics

Threads
1,213,506
Messages
6,114,027
Members
448,543
Latest member
MartinLarkin

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top