shorten sumproduct formula

mycroft99

New Member
Joined
Sep 26, 2009
Messages
20
Does anyone know how I can reduce or clean up this formula? It works but it looks like a dogs breakfast.

Essentially I want 10 conditions to be met before summing a particular range i.e. Data!$F$4:$GC$48. All conditions are the same except the 4th condition which varies from = $A$6 to = $A$12, and I have just added an additional 6 Sumproducts, changing the 4th reference each time.

Is there a way to have the 4th condition read "$A$6 or $A$7 or $A$8" etc..?


=((SUMPRODUCT((Data!$C$4:$C$48=B$4)*(Data!$E$4:$E$48=$A34)*(Data!$F$2:$GC$2=B$3)*(Data!$F$3:$GC$3=$A$6),Data!$F$4:$GC$48)+SUMPRODUCT((Data!$C$4:$C$48=B$4)*(Data!$E$4:$E$48=$A34)*(Data!$F$2:$GC$2=B$3)*(Data!$F$3:$GC$3=$A$7),Data!$F$4:$GC$48)+SUMPRODUCT((Data!$C$4:$C$48=B$4)*(Data!$E$4:$E$48=$A34)*(Data!$F$2:$GC$2=B$3)*(Data!$F$3:$GC$3=$A$8),Data!$F$4:$GC$48)+SUMPRODUCT((Data!$C$4:$C$48=B$4)*(Data!$E$4:$E$48=$A34)*(Data!$F$2:$GC$2=B$3)*(Data!$F$3:$GC$3=$A$9),Data!$F$4:$GC$48)+SUMPRODUCT((Data!$C$4:$C$48=B$4)*(Data!$E$4:$E$48=$A34)*(Data!$F$2:$GC$2=B$3)*(Data!$F$3:$GC$3=$A$10),Data!$F$4:$GC$48)+SUMPRODUCT((Data!$C$4:$C$48=B$4)*(Data!$E$4:$E$48=$A34)*(Data!$F$2:$GC$2=B$3)*(Data!$F$3:$GC$3=$A$11),Data!$F$4:$GC$48)+SUMPRODUCT((Data!$C$4:$C$48=B$4)*(Data!$E$4:$E$48=$A34)*(Data!$F$2:$GC$2=B$3)*(Data!$F$3:$GC$3=$A$12),Data!$F$4:$GC$48))
 

Excel Facts

When did Power Query debut in Excel?
Although it was an add-in in Excel 2010 & Excel 2013, Power Query became a part of Excel in 2016, in Data, Get & Transform Data.
Try this:
Code:
=SUMPRODUCT((Data!$C$4:$C$48=B$4)*(Data!$E$4:$E$48=$A34)*(Data!$F$2:$GC$2=B$3)*
ISNUMBER(MATCH(Data!$F$3:$GC$3,$A$6:$A$12,0)),Data!$F$4:$GC$48)
Is that something you can work with?
 
Upvote 0
Hiker95,

Not sure how I would go about that. Didn't try it as Ron's method looked easier for me. Thanks for the link though.

Ron,

That's gold Jerry, GOLD! It worked a treat but I am curious as to the ISNUMBER(MATCH(Data!$F$3:$GC$3,$A$6:$A$12,0) function, where the data matched is Text and not Number.

I love this site.
m99
 
Upvote 0
It doesn't matter whether the data is text or numeric

The ISNUMBER function here refers to the result of the MATCH formula. If there is a match then MATCH function returns a number (the relative position of the match in the lookup array), otherwise it returns #N/A error. ISNUMBER tests that value.
 
Upvote 0

Forum statistics

Threads
1,213,551
Messages
6,114,266
Members
448,558
Latest member
aivin

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