Need help with a SUMPRODUCT formula

MailmanClaims

New Member
Joined
Aug 29, 2018
Messages
2
Hello. I have been using multiple SUM(COUNTIFS( added together to search ranges across several columns that match certain terms. I would like to use SUMPRODUCT instead as it is more clean and flexible. Unfortunately I cannot get the SUMPRODUCT to work. Please have a look at my two formulas and tell me where I might be going wrong with my SUMPRODUCT.

Note that I am using named ranges (VCCs, VType, VDmg, VStatus) that refer to a column in another sheet of about 1500 items. All ranges are the same ('Sheet1'!B2:B1500, 'Sheet1'!C2:C1500, and so on).

The COUNTIFS formula I'm using (does not have the line breaks in excel, of course) is:

=SUM(COUNTIFS(VCCs,{"Name1","Name2"},VType,"GL",VDmg,{"BI";"BIPD"},VStatus,"Open"))
+SUM(COUNTIFS(VCCs,{"Name1","Name2"},VType,"GL",VDmg,{"BI";"BIPD"},VStatus,"ReOpen"))
+SUM(COUNTIFS(VCCs,{"Name1","Name2"},VType,"GL",VDmg,{"BI";"BIPD"},VStatus,"Subrogation"))


returns a total of 3, which is accurate.


The SUMPRODUCT formula (again, without the line breaks) is:


=SUMPRODUCT(ISNUMBER(MATCH(VCCs,{"Name1","Name2"},0))
*ISNUMBER(MATCH(VType,"GL",0))
*ISNUMBER(MATCH(VDmg,{"BI","BIPD"},0))
*ISNUMBER(MATCH(VStatus,{"Open","ReOpen","Subrogation"},0)))


but returns a total of 0.

Based on my understanding of these formulas they should be spitting out the same result, but they are not. Could anyone explain why that might be the case and suggest a fix?

Thank you very much.
 
Last edited by a moderator:

Excel Facts

Return population for a City
If you have a list of cities in A2:A100, use Data, Geography. Then =A2.Population and copy down.
try either of

=SUMPRODUCT(--(ISNUMBER(MATCH(VCCs,{"Name1","Name2"},0))),--(VType="GL"),--(ISNUMBER(MATCH(VDmg,{"BI","BIPD"},0))),--(ISNUMBER(MATCH(Vstatus,{"Open","ReOpen","Subrogation"},0))))

=SUMPRODUCT(ISNUMBER(MATCH(VCCs,{"Name1","Name2"},0))*(VType="GL")*ISNUMBER(MATCH(VDmg,{"BI","BIPD"},0))*ISNUMBER(MATCH(Vstatus,{"Open","ReOpen","Subrogation"},0)))
 
Upvote 0

Forum statistics

Threads
1,214,641
Messages
6,120,693
Members
448,979
Latest member
DET4492

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