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:

MailmanClaims

New Member
Joined
Aug 29, 2018
Messages
2
Bumping my thread as it has been almost a month with no reply. Hopefully someone will be able to help!
 

Dave Patton

Well-known Member
Joined
Feb 15, 2002
Messages
3,780
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)))
 

Forum statistics

Threads
1,082,360
Messages
5,364,939
Members
400,815
Latest member
Joaquin Phoenix

Some videos you may like

This Week's Hot Topics

  • populate from drop list with multiple tables
    Hi All, i have a drop list that displays data, what i want is when i select one of those from the list to populate text from different tables on...
  • Find list of words from sheet2 in sheet1 before a comma and extract text vba
    Hi Friends, Trying to find the solution on my task. But did not find suitable one to the need. Here is my query and sample file with details...
  • Dynamic Formula entry - VBA code sought
    Hello, really hope one of you experts can help with this - i've spent hours on this and getting no-where. .I have a set of data (more rows than...
  • Listbox Header
    Have a named range called "AccidentsHeader" Within my code I have: [CODE]Private Sub CommandButton1_Click() ListBox1.RowSource =...
  • Complex Heat Map using conditional formatting
    Good day excel world. I have a concern. Below link have a list of countries that carries each country unique data. [URL...
  • Conditional formatting
    Hi good morning, hope you can help me please, I have cells P4:P54 and if this cell is equal to 1 then i want row O to say "Fully Utilised" and to...
Top