Sumproduct question

bab01824

Board Regular
Joined
Apr 10, 2003
Messages
53
I use sumproduct often in the form;

Code:
SUMPRODUCT((RESULT="Y")*(MODULE="Fax")*(BETA="Y))
, where RESULT, MODULE and BETA are column ranges and I am looking for a count where all three criteria are met.

But now I have to count incidences where the RESULT could be "Y" OR "B" in addition to the other criteria. Other than a long formula like;

Code:
SUMPRODUCT((RESULT="Y")*(MODULE="Fax")*(BETA="Y))+SUMPRODUCT((RESULT="B")*(MODULE="Fax")*(BETA="Y))

is there a simpler way?

bb
 

Some videos you may like

Excel Facts

Square and cube roots
The =SQRT(25) is a square root. For a cube root, use =125^(1/3). For a fourth root, use =625^(1/4).

Zack Barresse

MrExcel MVP
Joined
Dec 9, 2003
Messages
10,881
Office Version
  1. 365
  2. 2010
Platform
  1. Windows
  2. Mobile
  3. Web
how about...

=SUMPRODUCT(or((RESULT="Y"),(RESULT="B"))*(MODULE="Fax")*(BETA="Y))
 

Joe4

MrExcel MVP, Junior Admin
Joined
Aug 1, 2002
Messages
55,916
Office Version
  1. 365
Platform
  1. Windows
Try this:

=SUMPRODUCT((RESULT={"Y","B"})*(MODULE="Fax")*(BETA="Y"))
 

Aladin Akyurek

MrExcel MVP
Joined
Feb 14, 2002
Messages
85,201
Three options: In order of flexibilty and speed...

=SUMPRODUCT(--ISNUMBER(MATCH(RESULT,{"Y","B"},0)),--(MODULE="Fax"),--(BETA="Y"))

=SUMPRODUCT(((RESULT="Y")+(RESULT="B")),--(MODULE="Fax"),--(BETA="Y"))

=SUMPRODUCT((RESULT={"Y","B"})*(MODULE="Fax")*(BETA="Y"))
 

Aladin Akyurek

MrExcel MVP
Joined
Feb 14, 2002
Messages
85,201

ADVERTISEMENT

firefytr said:
how about...

=SUMPRODUCT(or((RESULT="Y"),(RESULT="B"))*(MODULE="Fax")*(BETA="Y))

OR computes a scalar value, not an array, hence it won't work.
 

Zack Barresse

MrExcel MVP
Joined
Dec 9, 2003
Messages
10,881
Office Version
  1. 365
  2. 2010
Platform
  1. Windows
  2. Mobile
  3. Web
thank you Aladin,

i got to looking at that, and now see my folly. sorry bout the mis-post. fingers ahead of the mind :(

thank you for the correction!

i apologize bruce, didn't mean to screw up your post.
 

bab01824

Board Regular
Joined
Apr 10, 2003
Messages
53
I had tried the OR and it didn't work. The { } solution worked,

Thanks as always.

bb
 

Watch MrExcel Video

Forum statistics

Threads
1,122,560
Messages
5,596,842
Members
414,107
Latest member
Tigretto

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