Find min based on criteria, not to return zero values

projectile

Board Regular
Joined
Dec 14, 2007
Messages
193
I have this array which appears to work, however I do not want it to return zero values, just anything greater than zero.

Is this possible?

HTML:
{=MIN((DATASET!$A$2:$A$78956=A2)*DATASET!$Y$2:$Y$78956)}


I also wanted to use similar formula to return the SUPPLIER who is linked to this minimum value. The supplier is stored in column Z of the DATASET sheet. I have tried Googling a way to offset the above formula to return result of column Z instead of column Y, but not getting any where.. Would appreciate some help.

thanks
 

Excel Facts

What is the fastest way to copy a formula?
If A2:A50000 contain data. Enter a formula in B2. Select B2. Double-click the Fill Handle and Excel will shoot the formula down to B50000.
To get the minimum but not 0 try

{=MIN(IF(DATASET!$A$2:$A$78956=A2,IF(DATASET!$Y$2:$Y$78956<>0,DATASET!$Y$2:$Y$78956)))}

To get the supplier, I suggest trying VLOOKUP or INDEX/MATCH depending on your data.
to get started with these try googling them. I personally prefer videos as it explains and shows you at the same time how they work.

VLOOKUP - https://exceljet.net/tips/how-to-use-vlookup
INDEX/MATCH - https://www.youtube.com/watch?v=j5NMg9ONd84
 
Upvote 0
Hi Sinon, thanks for your reply. your formula worked thanks.

With regards to the second question to return another column of the min formula, I tried the follow but it returns #REF

Code:
{=INDEX(MIN((IF(DATASET!$A$2:$A$78956=A46,IF(DATASET!$Y$2:$Y$78956<>0,DATASET!$Y$2:$Y$78956)))),0,2)}

Any ideas where i'm going wrong?
 
Last edited:
Upvote 0
Thought this may have done the trick, but returns N/A




=INDEX(DATASET!$AH$2:$AH$78956,MATCH(MIN((IF(DATASET!$A$2:$A$78956=A50,IF(DATASET!$Y$2:$Y$78956<>0,DATASET!$Y$2:$Y$78956)))),$Y$2:$Y$78956,0))

PLease advise
 
Upvote 0
Thought this may have done the trick, but returns N/A

PLease advise

Sheet1 (processing)

Row\Col
A​
49​
50​
JAD
51​
3​
52​
2​
53​
supplier
54​
SUP-A
55​
SUP-Q
56​

A50 houses the condition of interest.

In A51 control+shift+enter, not just enter:
Rich (BB code):
=MIN(IF(DATASET!$A$2:$A$78956=A50,IF(ISNUMBER(1/DATASET!$Y$2:$Y$78956),
    DATASET!$Y$2:$Y$78956)))

In A52 control+shift+enter:
Rich (BB code):
<strike></strike>=SUM(IF(FREQUENCY(IF(DATASET!$A$2:$A$78956=A50,IF(ISNUMBER(1/DATASET!$Y$2:$Y$78956),
     IF(DATASET!$Y$2:$Y$78956=A51,MATCH(DATASET!$AH$2:$AH$78956,DATASET!$AH$2:$AH$78956,0)))),
     ROW(DATASET!$AH$2:$AH$78956)-ROW(DATASET!$AH$2)+1),1))<strike></strike>


In A54 control+shift+enter and copy down:
Rich (BB code):
=IF(ROWS(A$54:A54)<=$A$52,INDEX(DATASET!$AH$2:$AH$78956,MIN(IF(DATASET!$A$2:$A$78956=A$50,
    IF(DATASET!$Y$2:$Y$78956=A$51,IF(ISNA(MATCH(DATASET!$AH$2:$AH$78956,A$53:A53,0)),
    ROW(DATASET!$AH$2:$AH$78956)-ROW(DATASET!$AH$2)+1))))),"")

This set up picks out all distinct suppliers associated with the min value, computed using the criterion value in A50.
 
Upvote 0

Forum statistics

Threads
1,215,831
Messages
6,127,143
Members
449,363
Latest member
Yap999

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