How to lookup the minimum, 2nd minimum and 3rd minimum.........

M

Mark McDonough

Following up on a previous query..........I am able to look along a row of
values and return the name of the cheapest supplier thanks muchly toJohn
Topely and Bob Philips.

To obtain the name of the supplier I tried
=INDEX($B$1:$E$1,1,MATCH(MIN(IF($B2:$E2>0,$B2:$E2)),$B2:$E2,0))

as suggested and it works well.

Extending on that idea, how would I go about returning the name of the
supplier that had the next cheapest rate and the third cheapest given that I
have 24 suppliers. For the purpose of illustration, I have only shown 3 in
my example.

Site Supplier A Supplier B Supplier C
Bilo1 175000 150000 125000
Bilo2 125000 50000 60000
Bilo3 50000 60000 70000

Any help appreciated


Cheers

Mark
 
B

Bob Phillips

Second smallest

=INDEX($B$1:$E$1,1,MATCH(SMALL(IF($B2:$E2>0,$B2:$E2),2),$B2:$E2,0))

Third

=INDEX($B$1:$E$1,1,MATCH(SMALL(IF($B2:$E2>0,$B2:$E2),3),$B2:$E2,0))

--
HTH

Bob Phillips

(replace somewhere in email address with gmail if mailing direct)

Mark McDonough said:
Following up on a previous query..........I am able to look along a row of
values and return the name of the cheapest supplier thanks muchly toJohn
Topely and Bob Philips.

To obtain the name of the supplier I tried
=INDEX($B$1:$E$1,1,MATCH(MIN(IF($B2:$E2>0,$B2:$E2)),$B2:$E2,0))

as suggested and it works well.

Extending on that idea, how would I go about returning the name of the
supplier that had the next cheapest rate and the third cheapest given that I
have 24 suppliers. For the purpose of illustration, I have only shown 3 in
my example.

Site Supplier A Supplier B Supplier C
Bilo1 175000 150000 125000
Bilo2 125000 50000 60000
Bilo3 50000 60000 70000

Any help appreciated


Cheers

Mark



----== Posted via Newsfeeds.Com - Unlimited-Unrestricted-Secure Usenet News==----
http://www.newsfeeds.com The #1 Newsgroup Service in the World! 120,000+ Newsgroups
----= East and West-Coast Server Farms - Total Privacy via Encryption
=----
 
R

Roger Govier

Hi Mark

Try the array formula (Enter with Control+Shift+Enter)
{=INDEX($B$1:$E$1,1,MATCH(SMALL(IF($B2:$E2>0,$B2:$E2),COLUMN(A:A)),$B2:$E2,0))}
Copy across through successive columns.
Column(A:A) will find the first smallest. As you drag across that will
change to B:B etc to find the second smallest etc.
If there is no value that meets the test, for example if there are only
2 values out of the 3 entered, then it can't find the third smallest and
will return a #NUM error.

If you want to get rid of this, then wrap the whole formula in an error
trap
=IF(ISERROR(formula),"",formula)
 
M

Mark McDonough

This works very well.....Thank you.

Just trying to understand the formula though. I have a column of minimum
data so that I can probably get by with a simpler formula.

What is the COLUMN(A:A) and SMALL for. It seems to me to be redundant. The
formula I have used is exactly as presented below but the whole calculation
does not depend on column A at all.

Having used this formula, a major hurdle has been overcome at work and now
they want me to present it to the group - quite scared!!!
 
R

Roger Govier

Hi Mark

SMALL() uses arguments of 1, 2, 3 etc. to give the smallest value in a
range, the second smallest etc.
You can hard code these numbers into a formula, which means you have to
alter each formula as you copy it across the page.

COLUMN() returns the column number, COLUMN(A:A) will return 1, but as
you copy across from the first cell, then it changes to COLUMN(B:B),
COLUMN(C:C) etc. thereby stepping up the number in the argument for you
automatically so one formula can be copied across (and down) the sheet
as appropriate.

The fact that you are not using data in Column A is of no consequence,
it is merely fixing the result to be 1 in your starting formula.
 
M

Mark McDonough

Thanks for that enlightenment Roger.

Roger Govier said:
Hi Mark

SMALL() uses arguments of 1, 2, 3 etc. to give the smallest value in a
range, the second smallest etc.
You can hard code these numbers into a formula, which means you have to
alter each formula as you copy it across the page.

COLUMN() returns the column number, COLUMN(A:A) will return 1, but as you
copy across from the first cell, then it changes to COLUMN(B:B),
COLUMN(C:C) etc. thereby stepping up the number in the argument for you
automatically so one formula can be copied across (and down) the sheet as
appropriate.

The fact that you are not using data in Column A is of no consequence, it
is merely fixing the result to be 1 in your starting formula.
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top