Array Function Question

G

Guest

Hi,

I am using an array function to lookup maximum and minimum values between to
two dates (see below). The array function for MAX() works perfectly fine.
However, once I substitute MIN for MAX and hit ctrl+shift+enter, the output i
zero, even though this answer is wrong. (There are no observations with the
value of 0 in the dataset. Nor are there blank observations.)

Does anyone know why the array function with MIN doesn't work?

In advance, thanks for your help.

Henrik

WORKS
{=MAX(Stock_Data!$C$3:$C$1616*($A2<=Stock_Data!$A$3:$A$1616)*($K2>=Stock_Data!$A$3:$A$1616))}


DOESN'T WOR
{=MIN(Stock_Data!$C$3:$C$1616*($A2<=Stock_Data!$A$3:$A$1616)*($K2>=Stock_Data!$A$3:$A$1616))}
 
G

Guest

It's because when the cells don't match your criteria, the formula returns
FALSE...which equates to ZERO. So as soon as you have a non-matching
value...you get your minimum of zero.

Try this:

=MIN(IF(($A2<=Stock_Data!$A$3:$A$1616)*($K2>=Stock_Data!$A$3:$A$1616),Stock_Data!$C$3:$C$1616,10^10))

Remember to [Ctrl]+[Shift]+[Enter] to commit that array 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