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

AnyaK

New Member
Joined
Jun 5, 2017
Messages
26
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.
 

Some videos you may like

Excel Facts

What did Pito Salas invent?
Pito Salas, working for Lotus, popularized what would become to be pivot tables. It was released as Lotus Improv in 1989.

Marcelo Branco

MrExcel MVP
Joined
Aug 23, 2010
Messages
16,371
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)

A
B
C
D
E
F
G
H
I
J
K
1
Project​
Value1​
Value2​
Value3​
Search​
Result​
Helper​
2
xxx ProjectChocolate​
No​
ProjectChocolate​
4​
1​
3
zzzz​
No​
ProjectCarrot​
4
ProjectCarrot xyz​
Project Pecan​
1​
5
Project Pecan www​
Yes​
No​
1​
6
zzzz​
7
ProjectChocolate​
No​
No​
No​
1​
8
ProjectCarrot xyz​
Yes​

<tbody>
</tbody>


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:

AnyaK

New Member
Joined
Jun 5, 2017
Messages
26
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
 

Forum statistics

Threads
1,089,429
Messages
5,408,172
Members
403,188
Latest member
Sanjana Ramesh

This Week's Hot Topics

  • help please
    SORRY NOT ANY GOOD AT EXCEL SO HELP WOULD BE MUCH APPRECIATED this formula is in a sheet called ignore...
  • two formulas needed
    Hello, I'll try my best to explain this: First formula needed in Sheet1 cell A2: If Sheet1 cell B2 = Sheet2 cell B2 then return a 1. If not then...
  • Dynamic Counts
    Good afternoon, we are tidying up some data & the data seems to be growing quicker than we are tidying it up! What we confirm (by reviewing it...
  • Help Excel formula eliminate duplicate values and keep only 2 identical rows.
    as picture below column A has a duplicate value. but the values are not the same as the rule. sometimes 4 rows, sometimes 10 rows or 7 or 9...
  • Macro Compile Error Sub or Function not defined
    Hello, I am trying to run macros from a validation list, all macros have been created and run perfectly on there own but I'm getting a compile...
  • Last row combined with Current Region VBA
    I'm generally happy finding the last row of data through something like Lastrow = Cells(Rows.Count, "D").End(xlUp) but I don't always receive data...
Top