Problem with COUNTIF and wild character

alex_a

Board Regular
Joined
Feb 27, 2012
Messages
51
Good Morning,

I have the follwoing data in column C and D. in the C column i have multiple codes all of them start with the word QC. I need to count the numebr of "yes" in the column D. I am using an array formula like this:
SUMPRODUCT(C1:C20="QC*")*(D1:D20="Yes"). I get an erroo message (#Name!). What is wrong with this formula? Thanks.
 

Excel Facts

Formula for Yesterday
Name Manager, New Name. Yesterday =TODAY()-1. OK. Then, use =YESTERDAY in any cell. Tomorrow could be =TODAY()+1.
Sumproduct won't support wildcard use like that.

And you ENDED the sumproduct with the first ), which left (D1:D20="Yes)" as a standalone function..
SUMPRODUCT(C1:C20="QC*")*(D1:D20="Yes")

Which version of Excel are you using?
In XL2007 we have COUNTIFS
=COUNTIFS(C1:C20,"QC*",D1:D20,"Yes")
 
Upvote 0
COUNTIFS will be faster.

But if you intend to use SUMPRODUCT then you will have to use construct like below:
=SUMPRODUCT((LEFT(C1:C20,2)="QC")*(D1:D20="Yes"))
 
Upvote 0
If you know it always starts with a QC then just use the left function...
Also, you need to convert the trues and falses to 0's and 1's.

=SUMPRODUCT(--(LEFT(C1:C20,2)="QC")*(--(D1:D20="Yes")))
 
Upvote 0
If you know it always starts with a QC then just use the left function...
Also, you need to convert the trues and falses to 0's and 1's.

=SUMPRODUCT(--(LEFT(C1:C20,2)="QC")*(--(D1:D20="Yes")))
Double unaries are not required as * [multiplication] will coerce it to numbers.
 
Upvote 0
Thanks. It worked liek a charm.
I hav eanother question: If I want ato add another condition such as if the wild character is QC or blank, how can I modify the sumproduct or countif statement? Thanks.
 
Upvote 0
Maybe,

=SUMPRODUCT((LEFT(C1:C10,2)="QC")*(E1:E10="Yes"))+SUMPRODUCT((C1:C10="")*(E1:E10="Yes"))

Jai
 
Upvote 0
I hav eanother question: If I want ato add another condition such as if the wild character is QC or blank, how can I modify the sumproduct or countif statement? Thanks.

=SUMPRODUCT(--ISNUMBER(MATCH(LEFT(C1:C10,2),{"QC",""},0)),--(E1:E10="Yes"))
 
Upvote 0

Forum statistics

Threads
1,214,551
Messages
6,120,161
Members
448,948
Latest member
spamiki

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