Excel - non vba code - Associate a Text Phrase to a Group of Ranked Numbers

Richard2542

Board Regular
Joined
Apr 27, 2017
Messages
102
Office Version
  1. 365
  2. 2013
I have ranked a list of players by score (low to high using the Rank function) and wish to designate (using text) the present standing (1 to 5 places) of the player. If 2 players are ranked 1, the next lowest player(s) would be ranked 3, etc.
I would like to designate, via text in a Notes column adjacent to the player's name, the phrase 1st Place or Tied 1st and 2nd Place, etc. I would like to accomplish this by formula (non vba code).
 

Excel Facts

How to calculate loan payments in Excel?
Use the PMT function: =PMT(5%/12,60,-25000) is for a $25,000 loan, 5% annual interest, 60 month loan.
How about
C2&LOOKUP(C2,{1,2,3,4},{"st","nd","rd","th"})&" Place"&IF(COUNTIF($C$2:$C$6,C2)>1," Tied","")
 
Upvote 0
Thanks...formula worked really nice - I would like the ties to reflect the possible positions, e.g., if the 1st 2 players are tied for 1st, then the text should read "Tied - 1st and 2nd Place".
 
Upvote 0
Swap the formula round like this
=IF(COUNTIF($C$2:$C$8,C2)>1,"Tied ","")&C2&LOOKUP(C2,{1,2,3,4},{"st","nd","rd","th"})&" Place"

If 2 people are tied for 1st place they are not 1st & 2nd, just 1st.
also what would happen if 4 people tied?
 
Upvote 0
Maybe this variation of Fluff's formula?


ABCD
1NameScoreRankNotes
2a681Tied - 1st Place - 2nd Place
3b703Tied - 3rd Place - 5th Place
4c703Tied - 3rd Place - 5th Place
5d7466th Place
6e703Tied - 3rd Place - 5th Place
7f681Tied - 1st Place - 2nd Place

<tbody>
</tbody>


Worksheet Formulas
CellFormula
D2=IF(COUNTIF($C$2:$C$7,C2)>1,"Tied - ","")&C2&LOOKUP(C2,{1,2,3,4},{"st","nd","rd","th"})&" Place"&IF(COUNTIF($C$2:$C$7,C2)>1," - "&C2+COUNTIF($C$2:$C$7,C2)-1&LOOKUP(C2+COUNTIF($C$2:$C$7,C2)-1,{1,2,3,4},{"st","nd","rd","th"})&" Place","")

<tbody>
</tbody>

<tbody>
</tbody>
 
Last edited:
Upvote 0
Fluff...the two or more players tied for 1st would be shown in the notes section (each player - adjacent to their name): Tied - 1st and 2nd Place.
If there were a total of 10 players and each player had the same score (highly unusual) then each player would have the designation Tied 1st, 2nd, 3rd, 4th and 5th Place...a bit more complicated.
 
Upvote 0
Eric and Fluff - here's what I just tested: Player 1 and 2 are ranked 1 (formula displays "Tied - 1st Place - 2nd Place", Player 3 and 4 are ranked 3 (formula displays "Tied 3rd Place - 4th Place", Player 5 and 6 are ranked 5 (formula displays "Tied 5th - 6th Place".
The output is perfect till we get to Player 5 & 6 - since we are only awarding 5 places I need to eliminate 6th Place.
 
Upvote 0
Try:

Code:
=IF(C2>5,"",IF(COUNTIF($C$2:$C$7,C2)>1,"Tied - ","")&C2&LOOKUP(C2,{1,2,3,4},{"st","nd","rd","th"})&" Place"&IF(COUNTIF($C$2:$C$7,C2)>1," - "&MIN(C2+COUNTIF($C$2:$C$7,C2)-1,5)&LOOKUP(MIN(C2+COUNTIF($C$2:$C$7,C2)-1,5),{1,2,3,4},{"st","nd","rd","th"})&" Place",""))
 
Upvote 0
Eric...this works, absolutely brilliant - is there an enhancement that would eliminate "[FONT=Verdana,Arial,Tahoma,Calibri,Geneva,sans-serif]Tied - 5th Place - 5th Place" and just return "Tied - 5th Place"?
I can't tell you how much I appreciate your solution(s).[/FONT]
 
Upvote 0

Forum statistics

Threads
1,214,653
Messages
6,120,757
Members
448,991
Latest member
Hanakoro

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