What Function Do I Need

Peter100

Well-known Member
Joined
Apr 21, 2002
Messages
765
Hi

In A3 to B7 I have data as shown below, I want to display in E4 the minimum value of B3:B7 and in D4 the corresponding Option reference ie. A,B,C etc.

I cant lay the table out the other way round so as I could use a simple lookup.
Can anyone help please
Book1
ABCDE
2OptionValueMinimumValue
3A75OptionNoValue
4B22
5C67
6D45
7E12
8F99
Sheet1
 

Excel Facts

Why does 9 mean SUM in SUBTOTAL?
It is because Sum is the 9th alphabetically in Average, Count, CountA, Max, Min, Product, StDev.S, StDev.P, Sum, VAR.S, VAR.P.

Scott Huish

MrExcel MVP
Joined
Mar 17, 2004
Messages
19,958
Office Version
  1. 365
  2. 2010
Platform
  1. Windows
Will there ever be duplicate minimum values?
 

Kjuel

New Member
Joined
Sep 4, 2006
Messages
7
Try

C3=A3
C4=A4
...
C7=A7
(hide the column C)

E4 = MIN(B3:B7)
D4 = VLOOKUP(E4,B3:C7,2,FALSE)
 

Scott Huish

MrExcel MVP
Joined
Mar 17, 2004
Messages
19,958
Office Version
  1. 365
  2. 2010
Platform
  1. Windows
If there are no duplicates, you don't need a helper column.

formula in E3:
=MIN(B:B)

Formula in D3:
=INDEX(A:A,MATCH(E3,B:B,0))
 

Peter100

Well-known Member
Joined
Apr 21, 2002
Messages
765

ADVERTISEMENT

so unlikely I will say no

But youve raised an interesting point.
Would there be a way to indicate that two values were equal minimum ?

But lets leave that until later
 

Peter100

Well-known Member
Joined
Apr 21, 2002
Messages
765
Hi Hotpepper

It displayed the min Ok but put the text "option in D3. As index & match were on the column in total, I set the ranges to be A3:A8 & B3:B8 in both and this seems to work.

MANY THANKS

Index & Match I have yet to get to grips with fully.

Any ideas if there was a duplicate min value ?
 

Peter_SSs

MrExcel MVP, Moderator
Joined
May 28, 2005
Messages
50,694
Office Version
  1. 365
Platform
  1. Windows
Peter100

If I have understood correctly, here is one way of dealing with multiple minimums.

1. E4: =MIN(B3:B8)
2. F4: =COUNTIF(B3:B8,E4)
3. C3 (copied down): =IF(B3=$E$4,COUNTIF(B$3:B3,$E$4),"")
4. D4 (copied down): =IF(ROWS(D$4:D4)<=F$4,INDEX($A$3:$A$8,MATCH(ROWS(D$4:D4),$C$3:$C$8,0)),"")
Mr Excel.xls
ABCDEFG
1
2OptionValueMinimum Value
3A75 Option NoValueOccurrances
4B22 C122
5C121E
6D45  
7E122 
8F99 
9
Minimums
 

Forum statistics

Threads
1,141,847
Messages
5,708,950
Members
421,601
Latest member
Garlo

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
Top