Find Smallest and Next Smallest Value

Aniphilo

New Member
Joined
Oct 17, 2015
Messages
9
Hi,

The problem I am having is that my two formulas are finding the same result

Formula 1
=INDEX($D5:$D11,MATCH(SMALL($G5:$G11,1),$G5:$G11,0))

Formula 2
=INDEX($D5:$D11,MATCH(SMALL($G5:$G11,2),$G5:$G11,0))

D5:D11 (staff names)
G5:G11 (number of files)

I am trying to find the staff member with the lowest and then next lowest number of files.

If there are multiple staff with zero files would that make both formulas give the same result?

It's like I need the 2nd formula to calculate the smallest value not equal to Formula 1.

Thank you
 

Excel Facts

Return population for a City
If you have a list of cities in A2:A100, use Data, Geography. Then =A2.Population and copy down.
I have managed to do this with 2 columns, Formulas in K2 and J3 are Control shift enter then copy down
formula in J1 is not




DEFGHIJK
1jane 6
2peter 3 0phil
3phil 0 3peter
4geoff 0 4mark
5tony 8 5yvonne
6mark 4 6jane
7yvonne 5 8tony
8

<colgroup><col style="width: 30px; font-weight: bold;"><col style="width: 64px;"><col style="width: 64px;"><col style="width: 64px;"><col style="width: 64px;"><col style="width: 64px;"><col style="width: 64px;"><col style="width: 64px;"><col style="width: 64px;"></colgroup><tbody>
</tbody>

Spreadsheet Formulas
CellFormula
J2=SMALL($G$1:$G$7,1)
K2{=INDEX($D$1:$D$7,MATCH(J2,$G$1:$G$7,0))}
J3{=SMALL(IF($G$1:$G$7>J2,$G$1:$G$7),1)}
K3{=INDEX($D$1:$D$7,MATCH(J3,$G$1:$G$7,0))}
J4{=SMALL(IF($G$1:$G$7>J3,$G$1:$G$7),1)}
K4{=INDEX($D$1:$D$7,MATCH(J4,$G$1:$G$7,0))}
J5{=SMALL(IF($G$1:$G$7>J4,$G$1:$G$7),1)}
K5{=INDEX($D$1:$D$7,MATCH(J5,$G$1:$G$7,0))}
J6{=SMALL(IF($G$1:$G$7>J5,$G$1:$G$7),1)}
K6{=INDEX($D$1:$D$7,MATCH(J6,$G$1:$G$7,0))}
J7{=SMALL(IF($G$1:$G$7>J6,$G$1:$G$7),1)}
K7{=INDEX($D$1:$D$7,MATCH(J7,$G$1:$G$7,0))}

<tbody>
</tbody>
Formula Array:
Produce enclosing
{ } by entering
formula with CTRL+SHIFT+ENTER!

<tbody>
</tbody>
 
Upvote 0

Forum statistics

Threads
1,214,611
Messages
6,120,510
Members
448,967
Latest member
screechyboy79

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