ExcelBanter

ExcelBanter (https://www.excelbanter.com/)
-   Excel Worksheet Functions (https://www.excelbanter.com/excel-worksheet-functions/)
-   -   Array Function Question (https://www.excelbanter.com/excel-worksheet-functions/29674-array-function-question.html)

Henrik

Array Function Question
 
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 WORK
{=MIN(Stock_Data!$C$3:$C$1616*($A2<=Stock_Data!$A$ 3:$A$1616)*($K2=Stock_Data!$A$3:$A$1616))}

Ron Coderre

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

--
Regards,
Ron



All times are GMT +1. The time now is 05:36 AM.

Powered by vBulletin® Copyright ©2000 - 2024, Jelsoft Enterprises Ltd.
ExcelBanter.com