Formula to ignore blank cells

Dairy

New Member
Joined
Jul 26, 2005
Messages
24
Hi I have a sheet setup to count and sum the values as below, second is an array formula.

=SUMPRODUCT(('Fert Input'!E$12:E$151=B8)*('Fert Input'!F$12:F$151='Fert Mix'!$V$4))+SUMPRODUCT(('Fert Input'!G$12:G$151=B8)*('Fert Input'!H$12:H$151='Fert Mix'!$V$4))

=SUM(IF('Fert Input'!E$12:E$151=B8,IF('Fert Input'!F$12:F$151=$V$4,'Fert Input'!C$12:C$151,0),0))+SUM(IF('Fert Input'!G$12:G$151=B8,IF('Fert Input'!H$12:H$151=$V$4,'Fert Input'!C$12:C$151,0),0))

These work well but I wish to add a 3rd and 4th formula to count and sum < or = to

=SUMPRODUCT(('Fert Input'!E$12:E$151=B8)*('Fert Input'!F$12:F$151<=$N$1))+SUMPRODUCT(('Fert Input'!G$12:G$151=B8)*('Fert Input'!H$12:H$151<=$N$1))

=SUM(IF('Fert Input'!E$12:E$151=B8,IF('Fert Input'!F$12:F$151<=$N$1,'Fert Input'!C$12:C$151,0),0))+SUM(IF('Fert Input'!G$12:G$151=B8,IF('Fert Input'!H$12:H$151<=$N$1,'Fert Input'!C$12:C$151,0),0))

How might I stop the formulas above counting blank cells it finds in columns F and H?
 
Last edited:

Excel Facts

Using Function Arguments with nested formulas
If writing INDEX in Func. Arguments, type MATCH(. Use the mouse to click inside MATCH in the formula bar. Dialog switches to MATCH.
=SUMPRODUCT(ISNUMBER('Fert Input'!F$12:F$151)*('Fert Input'!E$12:E$151=B8)*('Fert Input'!F$12:F$151<=$N$1))+SUMPRODUCT(ISNUMBER('Fert Input'!H$12:H$151)*('Fert Input'!G$12:G$151=B8)*('Fert Input'!H$12:H$151<=$N$1))
 
Upvote 0
=SUMPRODUCT(ISNUMBER('Fert Input'!F$12:F$151)*('Fert Input'!E$12:E$151=B8)*('Fert Input'!F$12:F$151<=$N$1))+SUMPRODUCT(ISNUMBER('Fert Input'!H$12:H$151)*('Fert Input'!G$12:G$151=B8)*('Fert Input'!H$12:H$151<=$N$1))

Yes! works nicely. I can add the ISNUMBER as a third statement to the array formula.

=SUM(IF('Fert Input'!E$12:E$151=B8,IF('Fert Input'!F$12:F$151<=$N$1,IF(ISNUMBER('Fert Input'!F$12:F$151),'Fert Input'!C$12:C$151,0),0)))

Seems to work as well.

Cheers,

Daniel
 
Upvote 0

Forum statistics

Threads
1,214,982
Messages
6,122,580
Members
449,089
Latest member
Motoracer88

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