Rank by Group with Tiebreaker

BradH

New Member
Joined
Jan 25, 2010
Messages
44
I have searched a ton of posts to find this answer and have not been able to find the scenario that matches mine and works.

I want to sort as follows: (There are 300+ Teams in 35+ Divisions)

[TABLE="width: 500"]
<tbody>[TR]
[TD]Team[/TD]
[TD]Division[/TD]
[TD]Div Win %[/TD]
[TD]All Win %[/TD]
[TD]Rank[/TD]
[/TR]
[TR]
[TD]A[/TD]
[TD]1-5A[/TD]
[TD]1.000[/TD]
[TD].750[/TD]
[TD]1[/TD]
[/TR]
[TR]
[TD]B[/TD]
[TD]1-5A[/TD]
[TD].500[/TD]
[TD].800[/TD]
[TD]3[/TD]
[/TR]
[TR]
[TD]C[/TD]
[TD]2-5A[/TD]
[TD].500[/TD]
[TD].500[/TD]
[TD]1[/TD]
[/TR]
[TR]
[TD]D[/TD]
[TD]1-5A[/TD]
[TD]1.000[/TD]
[TD].600[/TD]
[TD]2[/TD]
[/TR]
</tbody>[/TABLE]

Div Win % is the #1 Rank factor, Overall Win % is the tiebreaker. If both are tied, then first match gets the spot.

I will be using this table to index/match the rank to build the standings, so there cannot be any ties.
 

Excel Facts

VLOOKUP to Left?
Use =VLOOKUP(A2,CHOOSE({1,2},$Z$1:$Z$99,$Y$1:$Y$99),2,False) to lookup Y values to left of Z values.
[TABLE="class: grid, align: left"]
<tbody>[TR]
[TD][TABLE="class: grid, align: left"]
<tbody>[TR]
[TH][/TH]
[TH]A[/TH]
[TH]B[/TH]
[TH]C[/TH]
[TH]D[/TH]
[TH]E[/TH]
[/TR]
[TR]
[TH]1[/TH]
[TD]
Team
[/TD]
[TD]
Division
[/TD]
[TD]
Div Win %
[/TD]
[TD]
All Win %
[/TD]
[TD]
Rank
[/TD]
[/TR]
[TR]
[TH]2[/TH]
[TD]
A​
[/TD]
[TD]
1-5A​
[/TD]
[TD]
1​
[/TD]
[TD]
0.75​
[/TD]
[TD]
1​
[/TD]
[/TR]
[TR]
[TH]3[/TH]
[TD]
B​
[/TD]
[TD]
1-5A​
[/TD]
[TD]
0.5​
[/TD]
[TD]
0.8​
[/TD]
[TD]
3​
[/TD]
[/TR]
[TR]
[TH]4[/TH]
[TD]
C​
[/TD]
[TD]
2-5A​
[/TD]
[TD]
0.5​
[/TD]
[TD]
0.5​
[/TD]
[TD]
1​
[/TD]
[/TR]
[TR]
[TH]5[/TH]
[TD]
D​
[/TD]
[TD]
1-5A​
[/TD]
[TD]
1​
[/TD]
[TD]
0.6​
[/TD]
[TD]
2​
[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
</tbody>[/TABLE]


[TABLE="class: grid, width: 0, align: left"]
<tbody>[TR]
[TD]Worksheet Formulas[/TD]
[/TR]
[TR]
[TD][TABLE="class: grid, width: 0, align: left"]
<tbody>[TR]
[TH]Cell[/TH]
[TH]Formula[/TH]
[/TR]
[TR]
[TH]E2[/TH]
[TD]=SUMPRODUCT(($B$2:$B$5=B2)*(($C$2:$C$5+$D$2:$D$5/100)>=C2+D2/100))[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
</tbody>[/TABLE]
 
Upvote 0
AlphaFrog, this works perfect unless C & D are both the same for multiple teams within a group. (Think beginning of season, nobody has any games played yet) In that case, the first to tie should get the spot, 2nd +1 etc.

This worked perfect on last seasons data, but I could not find any ties with both criteria.
 
Upvote 0
Row is a tie breaker
=SUMPRODUCT(($B$2:$B$5=B2)*(($C$2:$C$5+$D$2:$D$5/100-ROW($D$2:$D$5)/100000)>=C2+D2/100-ROW()/100000))
 
Last edited:
Upvote 0
Or try:

=COUNTIFS($B$2:$B$5,B2,$C$2:$C$5,">"&C2)+COUNTIFS($B$2:$B$5,B2,$C$2:$C$5,C2,$D$2:$D$5,">"&D2)+1
 
Upvote 0
Row is a tie breaker
=SUMPRODUCT(($B$2:$B$5=B2)*(($C$2:$C$5+$D$2:$D$5/100-ROW($D$2:$D$5)/100000)>=C2+D2/100-ROW()/100000))

Alpha,

This worked better, but it still has a flaw. Hopefully sharing sheets is allowed, I tried the two links on your profile and neither worked.

https://drive.google.com/open?id=1kGVSylt5goIUX6IJGTQmqCIasv87tCfx

I've filtered District 1-B. Only one team has won a District game and it properly ranks this team #1 . However, Weston should be ranked #2 because they have an overall Win % of 1.000 and Doyline should be #3 because they are only .750.

Oddly enough, if I sorted the entire sheet by District and then Opponent, it ranks correctly. Even though on Filter, they are in the same order...just not together. This is actually an acceptable workaround, but it would be better if I didn't have to do this sort.

Thanks for your help with this!
 
Upvote 0
This seemed to work...
=SUMPRODUCT(($B$2:$B$381=B2)*(($C$2:$C$381+$D$2:$D$381/100-ROW($D$2:$D$381)/1000000)>=C2+D2/100-ROW()/1000000))
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,181
Members
453,022
Latest member
Mohamed Magdi Tawfiq Emam

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