Help sumifs when criteria and corresponding lookup table can be blank

roberttkim

Board Regular
Joined
Mar 5, 2009
Messages
96
Please help. I have a sumifs formula
SUMIFS(BS!$L:$L,BS!$A:$A,Certification!$A5,BS!$B:$B,Certification!$B5)

However sometimes the information in column B can be blank and sometimes it's not. The corresponding table would have a blank or value in column B.
Just doing sumifs, it gives me a zero sum which is not correct. I think the fact that a blank cell criteria that should match to a blank column criteria is not being done.
Appreciate any assistance
 

Some videos you may like

Excel Facts

How to show all formulas in Excel?
Press Ctrl+` to show all formulas. Press it again to toggle back to numbers. The grave accent is often under the tilde on US keyboards.

jasonb75

Well-known Member
Joined
Dec 30, 2008
Messages
11,909
Office Version
  1. 365
Platform
  1. Windows
If I remember correctly, an empty cell in the criteria will have a value of 0, an empty cell in the criteria range will be blank.

To use an empty cell as a blank criteria, you need to enter either a single apostrophe or ="" into it.
 

Dave Patton

Well-known Member
Joined
Feb 15, 2002
Messages
4,563
Office Version
  1. 365
  2. 2010
Platform
  1. Windows
Try the SumProduct construct illustrated in the following example; the "+" provides the "or".

T10_1704b.xlsm
BCDG
1RegionItemQty
2EastPen2490
3WestPaper40
4EastPaper249
5East66
6WestPen20
1d
Cell Formulas
RangeFormula
G2G2=SUMPRODUCT(--((C2:C6=C2)+(C2:C6="")),--(B2:B6=B2),D2:D6)
 

Watch MrExcel Video

Forum statistics

Threads
1,122,469
Messages
5,596,329
Members
414,055
Latest member
mcarduner

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
Top