SUMPRODUCT with multiple criteria and arrays

fishewb

New Member
Joined
Jun 3, 2019
Messages
19
[TABLE="width: 512"]
<colgroup><col width="64" span="8" style="width:48pt"> </colgroup><tbody>[TR]
[TD="width: 64"][/TD]
[TD="class: xl65, width: 64, align: right"]1/1/2019[/TD]
[TD="class: xl65, width: 64, align: right"]2/1/2019[/TD]
[TD="class: xl65, width: 64, align: right"]3/1/2019[/TD]
[TD="class: xl65, width: 64, align: right"]4/1/2019[/TD]
[TD="class: xl65, width: 64, align: right"]5/1/2019[/TD]
[TD="class: xl65, width: 64, align: right"]6/1/2019[/TD]
[TD="class: xl65, width: 64, align: right"]7/1/2019[/TD]
[/TR]
[TR]
[TD]Product 1[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[/TR]
[TR]
[TD]Product 2[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]1[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]1[/TD]
[/TR]
[TR]
[TD]Product 3[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]1[/TD]
[TD="class: xl66, align: right"]1[/TD]
[TD="class: xl66, align: right"]2[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[/TR]
[TR]
[TD]Product 1[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[/TR]
[TR]
[TD]Product 2[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[/TR]
[TR]
[TD]Product 2[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[/TR]
[TR]
[TD]Product 1[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[/TR]
[TR]
[TD]Product 2[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]1[/TD]
[TD="class: xl66, align: right"]1[/TD]
[TD="class: xl66, align: right"]1[/TD]
[TD="class: xl66, align: right"]5[/TD]
[TD="class: xl66, align: right"]32[/TD]
[TD="class: xl66, align: right"]20[/TD]
[/TR]
[TR]
[TD]Product 3[/TD]
[TD="class: xl66, align: right"]60[/TD]
[TD="class: xl66, align: right"]45[/TD]
[TD="class: xl66, align: right"]49[/TD]
[TD="class: xl66, align: right"]40[/TD]
[TD="class: xl66, align: right"]62[/TD]
[TD="class: xl66, align: right"]41[/TD]
[TD="class: xl66, align: right"]69[/TD]
[/TR]
</tbody>[/TABLE]

Looking for help to get this SUMPRODUCT to work, using excel 2016

SUMPRODUCT((A2:A10="Product 1")*(A2:A10="Product 3")*(B1:H1=D1),B2:H10)

Thanks
 

Excel Facts

How to create a cell-sized chart?
Tiny charts, called Sparklines, were added to Excel 2010. Look for Sparklines on the Insert tab.
[TABLE="width: 512"]
<tbody>[TR]
[TD="width: 64"][/TD]
[TD="width: 64"]A[/TD]
[TD="class: xl65, width: 64, align: right"]B[/TD]
[TD="class: xl65, width: 64, align: right"]C[/TD]
[TD="class: xl65, width: 64, align: right"]D[/TD]
[TD="class: xl65, width: 64, align: right"]E[/TD]
[TD="class: xl65, width: 64, align: right"]F[/TD]
[TD="class: xl65, width: 64, align: right"]G[/TD]
[TD="class: xl65, width: 64, align: right"]H[/TD]
[/TR]
[TR]
[TD="width: 64"]1[/TD]
[TD="width: 64"][/TD]
[TD="class: xl65, width: 64, align: right"]1/1/2019[/TD]
[TD="class: xl65, width: 64, align: right"]2/1/2019[/TD]
[TD="class: xl65, width: 64, align: right"]3/1/2019[/TD]
[TD="class: xl65, width: 64, align: right"]4/1/2019[/TD]
[TD="class: xl65, width: 64, align: right"]5/1/2019[/TD]
[TD="class: xl65, width: 64, align: right"]6/1/2019[/TD]
[TD="class: xl65, width: 64, align: right"]7/1/2019[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]Product 1[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]Product 2[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]1[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]1[/TD]
[/TR]
[TR]
[TD]4[/TD]
[TD]Product 3[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]1[/TD]
[TD="class: xl66, align: right"]1[/TD]
[TD="class: xl66, align: right"]2[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[/TR]
[TR]
[TD]5[/TD]
[TD]Product 1[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[/TR]
[TR]
[TD]6[/TD]
[TD]Product 2[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[/TR]
[TR]
[TD]7[/TD]
[TD]Product 2[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[/TR]
[TR]
[TD]8[/TD]
[TD]Product 1[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]0[/TD]
[/TR]
[TR]
[TD]9[/TD]
[TD]Product 2[/TD]
[TD="class: xl66, align: right"]0[/TD]
[TD="class: xl66, align: right"]1[/TD]
[TD="class: xl66, align: right"]1[/TD]
[TD="class: xl66, align: right"]1[/TD]
[TD="class: xl66, align: right"]5[/TD]
[TD="class: xl66, align: right"]32[/TD]
[TD="class: xl66, align: right"]20[/TD]
[/TR]
[TR]
[TD]10[/TD]
[TD]Product 3[/TD]
[TD="class: xl66, align: right"]60[/TD]
[TD="class: xl66, align: right"]45[/TD]
[TD="class: xl66, align: right"]49[/TD]
[TD="class: xl66, align: right"]40[/TD]
[TD="class: xl66, align: right"]62[/TD]
[TD="class: xl66, align: right"]41[/TD]
[TD="class: xl66, align: right"]69[/TD]
[/TR]
</tbody>[/TABLE]

Looking for help to get this SUMPRODUCT to work, using excel 2016

SUMPRODUCT((A2:A10="Product 1")*(A2:A10="Product 3")*(B1:H1=D1),B2:H10)

Thanks

Sorry my table was incomplete. Added column and row references.
 
Upvote 0
Rather than supplying a formula that doesn't work, can you please explain (in words) what you are trying to do.
 
Upvote 0
Something like this


[Table="class: grid"][tr][td="bgcolor: #DCE6F1"][/td][td="bgcolor: #DCE6F1"]
A
[/td][td="bgcolor: #DCE6F1"]
B
[/td][td="bgcolor: #DCE6F1"]
C
[/td][td="bgcolor: #DCE6F1"]
D
[/td][td="bgcolor: #DCE6F1"]
E
[/td][td="bgcolor: #DCE6F1"]
F
[/td][td="bgcolor: #DCE6F1"]
G
[/td][td="bgcolor: #DCE6F1"]
H
[/td][td="bgcolor: #DCE6F1"]
I
[/td][td="bgcolor: #DCE6F1"]
J
[/td][td="bgcolor: #DCE6F1"]
K
[/td][td="bgcolor: #DCE6F1"]
L
[/td][/tr]
[tr][td="bgcolor: #DCE6F1"]
1
[/td][td][/td][td]
01/01/2019​
[/td][td]
02/01/2019​
[/td][td]
03/01/2019​
[/td][td]
04/01/2019​
[/td][td]
05/01/2019​
[/td][td]
06/01/2019​
[/td][td]
07/01/2019​
[/td][td][/td][td]
Products​
[/td][td]
Date​
[/td][td]
Result​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
2
[/td][td]
Product 1​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td][/td][td]
Product 1​
[/td][td]
03/01/2019​
[/td][td]
50​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
3
[/td][td]
Product 2​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td]
1​
[/td][td]
0​
[/td][td]
1​
[/td][td][/td][td]
Product 3​
[/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
4
[/td][td]
Product 3​
[/td][td]
0​
[/td][td]
1​
[/td][td]
1​
[/td][td]
2​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
5
[/td][td]
Product 1​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
6
[/td][td]
Product 2​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
7
[/td][td]
Product 2​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
8
[/td][td]
Product 1​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td]
0​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
9
[/td][td]
Product 2​
[/td][td]
0​
[/td][td]
1​
[/td][td]
1​
[/td][td]
1​
[/td][td]
5​
[/td][td]
32​
[/td][td]
20​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
10
[/td][td]
Product 3​
[/td][td]
60​
[/td][td]
45​
[/td][td]
49​
[/td][td]
40​
[/td][td]
62​
[/td][td]
41​
[/td][td]
69​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]
[/table]


Criteria in columns J:K

Formula L2
=SUMPRODUCT(SUMIF(A$2:A$10,J$2:J$3,INDEX(B$2:H$10,0,MATCH(K2,B$1:H$1,0))))

M.
 
Upvote 0
Rather than supplying a formula that doesn't work, can you please explain (in words) what you are trying to do.

Apologies, I'm new to posting.

I am trying to write utilize a function that can find more than one criteria in the same "column A" and sum all of each criteria found based on a particular month in row 1. In this example I'm looking for all of "Product 3" and "Product 2" in "3/1/2019"
 
Upvote 0
Something like this


[TABLE="class: grid"]
<tbody>[TR]
[TD="bgcolor: #DCE6F1"][/TD]
[TD="bgcolor: #DCE6F1"]
A
[/TD]
[TD="bgcolor: #DCE6F1"]
B
[/TD]
[TD="bgcolor: #DCE6F1"]
C
[/TD]
[TD="bgcolor: #DCE6F1"]
D
[/TD]
[TD="bgcolor: #DCE6F1"]
E
[/TD]
[TD="bgcolor: #DCE6F1"]
F
[/TD]
[TD="bgcolor: #DCE6F1"]
G
[/TD]
[TD="bgcolor: #DCE6F1"]
H
[/TD]
[TD="bgcolor: #DCE6F1"]
I
[/TD]
[TD="bgcolor: #DCE6F1"]
J
[/TD]
[TD="bgcolor: #DCE6F1"]
K
[/TD]
[TD="bgcolor: #DCE6F1"]
L
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
1
[/TD]
[TD][/TD]
[TD]
01/01/2019​
[/TD]
[TD]
02/01/2019​
[/TD]
[TD]
03/01/2019​
[/TD]
[TD]
04/01/2019​
[/TD]
[TD]
05/01/2019​
[/TD]
[TD]
06/01/2019​
[/TD]
[TD]
07/01/2019​
[/TD]
[TD][/TD]
[TD]
Products​
[/TD]
[TD]
Date​
[/TD]
[TD]
Result​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
2
[/TD]
[TD]
Product 1​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD][/TD]
[TD]
Product 1​
[/TD]
[TD]
03/01/2019​
[/TD]
[TD]
50​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
3
[/TD]
[TD]
Product 2​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
1​
[/TD]
[TD]
0​
[/TD]
[TD]
1​
[/TD]
[TD][/TD]
[TD]
Product 3​
[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
4
[/TD]
[TD]
Product 3​
[/TD]
[TD]
0​
[/TD]
[TD]
1​
[/TD]
[TD]
1​
[/TD]
[TD]
2​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
5
[/TD]
[TD]
Product 1​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
6
[/TD]
[TD]
Product 2​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
7
[/TD]
[TD]
Product 2​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
8
[/TD]
[TD]
Product 1​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD]
0​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
9
[/TD]
[TD]
Product 2​
[/TD]
[TD]
0​
[/TD]
[TD]
1​
[/TD]
[TD]
1​
[/TD]
[TD]
1​
[/TD]
[TD]
5​
[/TD]
[TD]
32​
[/TD]
[TD]
20​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
10
[/TD]
[TD]
Product 3​
[/TD]
[TD]
60​
[/TD]
[TD]
45​
[/TD]
[TD]
49​
[/TD]
[TD]
40​
[/TD]
[TD]
62​
[/TD]
[TD]
41​
[/TD]
[TD]
69​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]


Criteria in columns J:K

Formula L2
=SUMPRODUCT(SUMIF(A$2:A$10,J$2:J$3,INDEX(B$2:H$10,0,MATCH(K2,B$1:H$1,0))))

M.

Thank you, this does work. Is it possible to simplify the functions and only use SUMPRODUCT?
 
Upvote 0
If you just want sumproduct, try


Excel 2013/2016
ABCDEFGHIJK
101/01/201901/02/201901/03/201901/04/201901/05/201901/06/201901/07/201901/03/2019
2Product 10000000Product 150
3Product 20000101Product 3
4Product 30112000
5Product 10000000
6Product 20000000
7Product 20000000
8Product 10000000
9Product 2011153220
10Product 360454940624169
Dashboard
Cell Formulas
RangeFormula
K2=SUMPRODUCT(((A2:A10=J2)+(A2:A10=J3))*(B1:H1=K1),B2:H10)
 
Upvote 0
Thank you, this does work. Is it possible to simplify the functions and only use SUMPRODUCT?

I believe the formula i've suggested should be faster (more efficient) than other that uses SUMPRODUCT only.

M.
 
Upvote 0
You're welcome, but as Marcelo has said, his formula is a better way of doing it.
 
Upvote 0

Forum statistics

Threads
1,223,925
Messages
6,175,422
Members
452,641
Latest member
Arcaila

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