XL: How to Rank Duplicate Values SequentiallyID: Q152567
|
If a row or column of cells contains duplicate values, the RANK function
assigns the same rank value to every occurrence of the duplicate value.
This article describes a formula that you can use to assign a unique rank
for all numbers in a range, even if the range includes duplicate values.
To assign a unique rank for all numbers in a range, use the following
formula:
=SUM(1*Cell>=Range))-(SUM(1*(Cell=Range))-1)/2
where "cell" is the relative address of the cell containing one of the
values to be ranked, and "range" is the absolute address of the range
containing all of the values. This formula assigns a unique rank to every
value in a range, in ascending order.
A1: 100 B1:
A2: 75 B2:
A3: 100 B3:
A4: 75 B4:
A5: 50 B5:
=SUM(1*(A1>$A$1:$A$5))+1+IF(ROW(A1)-ROW($A$1)=0,0,
SUM(1*(A1=OFFSET($A$1,0,0,INDEX(ROW(A1)-ROW($A$1)+1,1)-1,1))))
NOTE: The formula must be entered as an array formula. To enter a
formula as an array formula in Microsoft Excel for Windows, press
CTRL+SHIFT+ENTER. In Microsoft Excel for the Macintosh, press
COMMAND+ENTER.
A1: 100 B1: 4
A2: 75 B2: 2
A3: 100 B3: 5
A4: 75 B4: 3
A5: 50 B5: 1
A1: 100 B1:
A2: 75 B2:
A3: 100 B3:
A4: 75 B4:
A5: 50 B5:
=SUM(1*(A1<$A$1:$A$5))+1+IF(ROW(A1)-ROW($A$1)=0,0,
SUM(1*(A1=OFFSET($A$1,0,0,INDEX(ROW(A1)-ROW($A$1)+1,1)-1,1))))
NOTE: The formula must be entered as an array formula. To enter a
formula as an array formula in Microsoft Excel for Windows, press
CTRL+SHIFT+ENTER. In Microsoft Excel for the Macintosh, press
COMMAND+ENTER.
A1: 100 B1: 1
A2: 75 B2: 3
A3: 100 B3: 2
A4: 75 B4: 4
A5: 50 B5: 5
A1: 100 B1: 75 C1: 100 D1: 75 E1: 50
A2: B2: C2: D2: E2:
=SUM(1*(A1<$A$1:$E$1))+1+IF(COLUMN(A1)-COLUMN($A$1)=0,0,
SUM(1*(A1=OFFSET($A$1,0,0,INDEX(COLUMN(A1)-COLUMN($A$1)+1,1)-1))))
NOTE: The above formula must be entered as an array formula. To
enter a formula as an array formula in Microsoft Excel for Windows,
press CTRL+SHIFT+ENTER. In Microsoft Excel for the Macintosh, press
COMMAND+ENTER.
A1: 100 B1: 75 C1: 100 D1: 75 E1: 50
A2: 4 B2: 2 C2: 5 D2: 3 E2: 1
A1: 100 B1: 75 C1: 100 D1: 75 E1: 50
A2: B2: C2: D2: E2:
=SUM(1*A1<A1:E1))+1+IF(COLUMN(A1)-COLUMN(A1)=0,0,
SUM(1*(A1=OFFSET(A1,0,0,1,INDEX(COLUMN(A1)-COLUMN(A1)+1,1)-1))))
NOTE: The above formula must be entered as an array formula. To
enter a formula as an array formula in Microsoft Excel for Windows,
press CTRL+SHIFT+ENTER. In Microsoft Excel for the Macintosh, press
COMMAND+ENTER.
A1: 100 B1: 75 C1: 100 D1: 75 E1: 50
A2: 1 B2: 3 C2: 2 D2: 4 E2: 5
Additional query words: 5.00a 5.00c 97 8.00 XL97 XL98
Keywords : xlformula xllist
Version : WINDOWS:5.0,5.0c,7.0,7.0a,97; MACINTOSH:5.0,98
Platform : MACINTOSH WINDOWS
Issue type : kbhowto
Last Reviewed: July 30, 1999