Opal said:
I am using the following formula:
'=IF(SUMPRODUCT(('Assess'!$H$3:$H$189="Temp")
*('Assess'!$J$3:$J$189<$B$15)*('Assess'!$M$3:$M$189="N")
*('Assess'!$A$3:$A$189=A16)*1),
SUMPRODUCT(('Assess'!$H$3:$H$189="Temp")
*('Assess'!$J$3:$J$189<$B$15)*('Assess'!$M$3:$M$189="N")
*('Assess'!$A$3:$A$189=A16)*1),0)
[....]
In column $M$3:$M$189 there are also
blank cells and I want to count these as if they
were "N" as well. How can I do this?
If the only expected values are, for example, "Y" in addition to "N" and
blank, you could simply change ="N" to <>"Y". To wit:
=SUMPRODUCT(('Assess'!$H$3:$H$189="Temp")
*('Assess'!$J$3:$J$189<$B$15)
*('Assess'!$M$3:$M$189<>"Y")
*('Assess'!$A$3:$A$189=A16))
Otherwise:
=SUMPRODUCT(('Assess'!$H$3:$H$189="Temp")
*('Assess'!$J$3:$J$189<$B$15)
*('Assess'!$M$3:$M$189="N"+'Assess'!$M$3:$M$189="")
*('Assess'!$A$3:$A$189=A16))
The (...+...) form is a way of expressing OR(); the "+" alternative is
needed in this context.
Note the other simplifications:
1. Omitted "*1". It seems useless in this context.
2. Omitted IF(). I don't see what IF(SUMPRODUCT(...),SUMPRODUCT(...),0)
accomplishes that simply SUMPRODUCT(...) does not. I believe the IF()
condition is FALSE only when SUMPRODUCT(...) is zero in the first place.
It would make sense if you had written
IF(ISNUMBER(SUMPRODUCT(...)),SUMPRODUCT(...),0). But I don't believe your
SUMPRODUCT formula can result in an error unless there is an error in a
referenced cell. And in that case, it could be better to put the
SUMPRODUCT
formula into a helper cell and write: IF(ISNUMBER(X1),X1,0).
----- original message -----
Opal said:
I am running Excel 2003 and I am trying to
count a range of data for charting.
I am using the following formula:
'=IF(SUMPRODUCT(('Assess'!$H$3:$H$189="Temp")*('Assess'!$J$3:$J$189<$B
$15)*('Assess'!$M$3:$M$189="N")*('Assess'!$A$3:$A$189=A16)
*1),SUMPRODUCT(('Assess'!$H$3:$H$189="Temp")*('Assess'!$J$3:$J$189<$B
$15)*('Assess'!$M$3:$M$189="N")*('Assess'!$A$3:$A$189=A16)*1),0)
It works great....except...
In column $M$3:$M$189 there are also
blank cells and I want to count these as if they
were "N" as well. How can I do this?