INDEX-MATCH with MIN across multiple columns? #N/A help needed

ADJuto

New Member
Joined
Sep 1, 2016
Messages
3
It's best to start with sample data:

TypeRipe_qty
Rotten_qty
Color
apple
6
3
red
apple
4
golden
banana
12
12
yellow
orange
31
orange
apricot
14
13
pink
apricot
brown
melon
9
1
green
strawberry
red
plum
7
10

<tbody>
</tbody>

















The results should answer the question: "for each type of fruit, what is the color of the lowest quantity, regardless of ripe/rotten status?"
----meaning, I don't really care whether the # is associated with Ripe or Rotten; I just need to know the color of the lowest number
----cells which are blank are truly blank. no values exist, but when encountered, some default value is set like '20'

Expected Results Table

Type
Color (formula needed here)
'manual answer' + notes
apple
red
3 is the minimum value, and that matches red. the blank cell in the golden row is either ignored or replaced with the default value of 20
banana
yellow
12
orange
orange
31 is the minimum value. Replacement of the empty cell with the default value of '20' would yield an incorrect answer based on the arbitrary value. Take the actual values when one is present.
apricot
pink
13
melongreen
1
strawberry
red
absent any values in either column.
plum
{formula}?
7 and the answer provided by the formula will be 'zzNoColor'

<tbody>
</tbody>

























Any ideas or strategies?
 

Excel Facts

Did you know Excel offers Filter by Selection?
Add the AutoFilter icon to the Quick Access Toolbar. Select a cell containing Apple, click AutoFilter, and you will get all rows with Apple
Maybe:

ABCDEFGH
1TypeRipe_qtyRotten_qtyColorTypeColor
2apple63redapplered
3apple4goldenbananayellow
4banana1212yelloworangeorange
5orange31orangeapricotpink
6apricot1413pinkmelongreen
7apricotbrownstrawberryred
8melon91greenplum
9strawberryred
10plum710

<tbody>
</tbody>
Sheet11

Worksheet Formulas
CellFormula
G2=LOOKUP(2,1/(($A$2:$A$10=F2)*(($B$2:$B$10=MAX($B$2:$C$10*($A$2:$A$10=F2)))+($C$2:$C$10=MAX($B$2:$C$10*($A$2:$A$10=F2))))),$D$2:$D$10)&""

<tbody>
</tbody>

<tbody>
</tbody>
 
Upvote 0
A somewhat shorter version of the formula:

=LOOKUP(2,1/(($A$2:$A$10=F2)*MMULT(--($B$2:$C$10=MAX($B$2:$C$10*($A$2:$A$10=F2))),{1;1})),$D$2:$D$10)&""
 
Upvote 0

Forum statistics

Threads
1,214,991
Messages
6,122,628
Members
449,095
Latest member
bsb1122

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