Position of Nth Smallest/Largest Value with Duplicates

thabhfy

New Member
Joined
Mar 15, 2017
Messages
2
I have a table with 3 columns. Column A is the color, column B is the class, and column C is the value. Classes are unique, and one color can have multiple values. The values can be the same.

I'm trying to find the lowest 5 values in the range and the corresponding class for an specific color. This is working fine with small, match, and index formulas:
Lowest value:
Code:
=SMALL(IF($A$4:$A$23=$F$1,$C$4:$C$23),1)

Corresponding class:
Code:
=INDEX($B$4:$B$23,MATCH(SMALL(IF($A$4:$A$23=$F$1,$C$4:$C$23),1),$C$4:$C$23,0))

I'm changing the k in small to be 1/2/3/4 or 5. Assuming color Blue is the criteria, For 1, it returns -464 as the value and R as the class... and so on.

My problem is when the value is the same. For 4, it returns -16 for value and M as the class. For 5 the same thing is returned, and for 6 it returns-15 for the value and Q for the class. I'd like the 5th lowest value to be -16, class P.

Table Example:

Color Class Value
Green B -90
Yellow C -50
Yellow D -49
Yellow E -41
Orange F -38
Green G -35
Green H -30
Blue I -27
Green J -25
Yellow K -21
Blue L -20
Blue M -16
Yellow N -19
Yellow O -19
Blue P -16
Blue Q -15
Blue R -464
 

Excel Facts

What does custom number format of ;;; mean?
Three semi-colons will hide the value in the cell. Although most people use white font instead.
Assuming I'm understanding correctly then maybe something like...

Unknown
ABCDEFG
1ColorClassValueBlue
2GreenB-901-464R
3YellowC-502-27I
4YellowD-493-20L
5YellowE-414-16M
6OrangeF-385-16P
7GreenG-35
8GreenH-30
9BlueI-27
10GreenJ-25
11YellowK-21
12BlueL-20
13BlueM-16
14YellowN-19
15YellowO-19
16BlueP-16
17BlueQ-15
18BlueR-464

<tbody>
</tbody>
Sheet6

Array Formulas
CellFormula
F2{=SMALL(IF($A$2:$A$18=$F$1,$C$2:$C$18),E2)}
G2{=INDEX($B$2:$B$18,SMALL(IF($C$2:$C$18=F2,ROW($C$2:$C$18)-ROW($C$2)+1),COUNTIF($F$2:F2,F2)))}

<tbody>
</tbody>
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself

<tbody>
</tbody>
 
Upvote 0

Forum statistics

Threads
1,216,929
Messages
6,133,559
Members
449,812
Latest member
briarlynn_daisy

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