Sumproduct based on substring?

A

altopalo

Hi -

I have a worksheet that has bug titles in column B and priority in
column C.

We have developed standard naming conventions for the bug title. For
example:

- MC: the Member Center has a bad help link in the header
- FP: the Front Page has a broken image in the header

I want to get a count of the bugs that contain a sub string of the
title (e.g. "MC" or "FP") and also have a certain Priority level in
column C.

I've tried these without success:

=SUMPRODUCT((B32:B1000="MC")*(C32:C1000="P1"))
=SUMPRODUCT((B32:B1000="*MC*")*(C32:C1000="P1"))
=SUMPRODUCT((B32:B1000=*MC*)*(C32:C1000="P1"))
=SUMPRODUCT((B32:B1000,*MC*)*(C32:C1000="P1"))

Any help would be greatly appreciated!!
 
B

Biff

Hi!

Try this:

=SUMPRODUCT(--(ISNUMBER(SEARCH("MC:",B32:B1000))),--(C32:C100="P1"))

Better:

Use cells to hold the criteria:

A1 = MC:
B1 = P1

=SUMPRODUCT(--(ISNUMBER(SEARCH(A1,B32:B1000))),--(C32:C100=B1))

Including the colon with the string helps reduce any false positives.

Biff
 
R

RagDyer

Try this:

=SUMPRODUCT((ISNUMBER(SEARCH("MC",B32:B1000)))*(C32:C1000="P1"))
--
HTH,

RD
==============================================
Please keep all correspondence within the Group, so all may benefit!
==============================================
 
A

altopalo

Thank you!!!!


=SUMPRODUCT((ISNUMBER(SEARCH("MC",B32:B1000)))*(C32:C1000="P1"))

worked beautifully
 
R

RagDyeR

I guess the reason it worked beautifully was because it didn't contain a
typo, leaving out a "0".<vbg>

Appreciate the feed-back.

--

Regards,

RD
--------------------------------------------------------------------
Please keep all correspondence within the Group, so all may benefit !
--------------------------------------------------------------------


message
Thank you!!!!


=SUMPRODUCT((ISNUMBER(SEARCH("MC",B32:B1000)))*(C32:C1000="P1"))

worked beautifully
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top