Sumproduct to Count Rows Meeting Multiple AND/OR Criteria - is there a Better/Easier Way?

AnyaK

New Member
Joined
Jun 5, 2017
Messages
36
Office Version
  1. 365
Platform
  1. Windows
Hello,

Please can you help me?

I have one column, AH, with names of different departments of our organisation.

Columns C,D and F contain health information as to whether or not clients are disabled.

I want to count how many clients of 3 of our departments have either "No" entered into either or all rows within C,D and F, or for whom their rows in C,D, and F are blank. I've tried so many variations of:

=SUMPRODUCT(--(--MMULT(ISNUMBER(SEARCH({"*ProjectChocolate*","*ProjectCarrot*","*Project Pecan*"},AH2:AH3000)),{1;1;1})>0)*((ISBLANK(C2:C3000))+(D2:D3000="No")+(ISBLANK(D2:D3000))+(F2:F3000="No")+(ISBLANK(F2:F3000))))


With this formula, I get a "VALUE" error.

Some other variations gave a resulting number which was 3 times the total number of clients in these projects, so clearly that was wrong too.

I'd really be so very grateful for any help as I'm literally in tears.

Thanks,

AnyaK


P.S. Please, please forgive that I cannot upload any examples; my employer prohibits this.
 

Excel Facts

Pivot Table Drill Down
Double-click any number in a pivot table to create a new report showing all detail rows that make up that number
I would use a Helper column

See if this example helps - to make things easier i used column A (Project) instead of column AH (adjust to suit)

[TABLE="class: grid"]
<tbody>[TR]
[TD="bgcolor: #DCE6F1"][/TD]
[TD="bgcolor: #DCE6F1"]
A
[/TD]
[TD="bgcolor: #DCE6F1"]
B
[/TD]
[TD="bgcolor: #DCE6F1"]
C
[/TD]
[TD="bgcolor: #DCE6F1"]
D
[/TD]
[TD="bgcolor: #DCE6F1"]
E
[/TD]
[TD="bgcolor: #DCE6F1"]
F
[/TD]
[TD="bgcolor: #DCE6F1"]
G
[/TD]
[TD="bgcolor: #DCE6F1"]
H
[/TD]
[TD="bgcolor: #DCE6F1"]
I
[/TD]
[TD="bgcolor: #DCE6F1"]
J
[/TD]
[TD="bgcolor: #DCE6F1"]
K
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
1
[/TD]
[TD]
Project​
[/TD]
[TD][/TD]
[TD]
Value1​
[/TD]
[TD]
Value2​
[/TD]
[TD][/TD]
[TD]
Value3​
[/TD]
[TD][/TD]
[TD]
Search​
[/TD]
[TD]
Result​
[/TD]
[TD][/TD]
[TD]
Helper​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
2
[/TD]
[TD]
xxx ProjectChocolate​
[/TD]
[TD][/TD]
[TD]
No​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]
ProjectChocolate​
[/TD]
[TD]
4​
[/TD]
[TD][/TD]
[TD]
1​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
3
[/TD]
[TD]
zzzz​
[/TD]
[TD][/TD]
[TD][/TD]
[TD]
No​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]
ProjectCarrot​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
4
[/TD]
[TD]
ProjectCarrot xyz​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]
Project Pecan​
[/TD]
[TD][/TD]
[TD][/TD]
[TD]
1​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
5
[/TD]
[TD]
Project Pecan www​
[/TD]
[TD][/TD]
[TD][/TD]
[TD]
Yes​
[/TD]
[TD][/TD]
[TD]
No​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]
1​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
6
[/TD]
[TD]
zzzz​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
7
[/TD]
[TD]
ProjectChocolate​
[/TD]
[TD][/TD]
[TD]
No​
[/TD]
[TD]
No​
[/TD]
[TD][/TD]
[TD]
No​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]
1​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
8
[/TD]
[TD]
ProjectCarrot xyz​
[/TD]
[TD][/TD]
[TD][/TD]
[TD]
Yes​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]


Search list in H2:H4

Helper column
Formula in K2 copied down
=IF(SUMPRODUCT(--ISNUMBER(SEARCH(H$2:H$4,A2)))=0,"",IF(COUNTIF(C2:D2,"No")+(F2="No")+(COUNTIF(C2:D2,"")+(F2="")=3),1,""))

I2
=SUM(K2:K7)

M.
 
Last edited:
Upvote 0
Hi Marcelo,

I just wanted to say a huge thank you for your help. This worked perfectly.

Apologies for the delayed reply, I've been unwell, so was offline for a time.

Thanks again,

AnyaK
 
Upvote 0

Forum statistics

Threads
1,223,897
Messages
6,175,269
Members
452,628
Latest member
dd2

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