Multiple Criteria Sumifs in Multiple Columns

chowyg

New Member
Joined
Jul 20, 2011
Messages
11
My table is below. I want to basically do a sum if with multiple criteria, but multiple criteria in multiple columns. I know how to do multiple criteria in a single column which is done like this "=SUM(SUMIFS(C2:C17,A2:A17,{"Europe","USA"},B2:B17,"Alpha"))"... but I'm trying to take it one step further and add in "Bravo" as well.

If this were a math function I want to do basically this. (X+Y)*(A+B), which is four functions. X*A, X*B, Y*A and Y*B. I need a formula that can sum the results using the multiple criteria. (Europe+USA)*(Alpha+Bravo).

Sum the criteria (Europe*Alpha, Europe* Bravo, USA*Alpha, USA*Bravo).

I been working on this for some time, it's quite stressful. I know the geniuses on here can help me resolve this. If this is confusing, please let me know and I will try to simply my needs better. Thanks in advance!



[TABLE="width: 192"]
<colgroup><col width="64" span="3" style="width:48pt"> </colgroup><tbody>[TR]
[TD="width: 64"]Region[/TD]
[TD="width: 64"]Team[/TD]
[TD="width: 64"]Sales[/TD]
[/TR]
[TR]
[TD]ASIA[/TD]
[TD]Alpha[/TD]
[TD="align: right"]30[/TD]
[/TR]
[TR]
[TD]ASIA[/TD]
[TD]Bravo[/TD]
[TD="align: right"]40[/TD]
[/TR]
[TR]
[TD]ASIA[/TD]
[TD]Alpha[/TD]
[TD="align: right"]110[/TD]
[/TR]
[TR]
[TD]ASIA[/TD]
[TD]Bravo[/TD]
[TD="align: right"]120[/TD]
[/TR]
[TR]
[TD]Brazil[/TD]
[TD]Alpha[/TD]
[TD="align: right"]70[/TD]
[/TR]
[TR]
[TD]Brazil[/TD]
[TD]Bravo[/TD]
[TD="align: right"]80[/TD]
[/TR]
[TR]
[TD]Brazil[/TD]
[TD]Alpha[/TD]
[TD="align: right"]150[/TD]
[/TR]
[TR]
[TD]Brazil[/TD]
[TD]Bravo[/TD]
[TD="align: right"]160[/TD]
[/TR]
[TR]
[TD]Europe[/TD]
[TD]Alpha[/TD]
[TD="align: right"]10[/TD]
[/TR]
[TR]
[TD]Europe[/TD]
[TD]Bravo[/TD]
[TD="align: right"]20[/TD]
[/TR]
[TR]
[TD]Europe[/TD]
[TD]Alpha[/TD]
[TD="align: right"]90[/TD]
[/TR]
[TR]
[TD]Europe[/TD]
[TD]Bravo[/TD]
[TD="align: right"]100[/TD]
[/TR]
[TR]
[TD]USA[/TD]
[TD]Alpha[/TD]
[TD="align: right"]50[/TD]
[/TR]
[TR]
[TD]USA[/TD]
[TD]Bravo[/TD]
[TD="align: right"]60[/TD]
[/TR]
[TR]
[TD]USA[/TD]
[TD]Alpha[/TD]
[TD="align: right"]130[/TD]
[/TR]
[TR]
[TD]USA[/TD]
[TD]Bravo[/TD]
[TD="align: right"]140[/TD]
[/TR]
</tbody>[/TABLE]
 

Excel Facts

Fastest way to copy a worksheet?
Hold down the Ctrl key while dragging tab for Sheet1 to the right. Excel will make a copy of the worksheet.
You can use more than 1 criteria using SUMPRODCT:

Try this formula:

=SUMPRODUCT((B2:B17="Europe")*(C2:C17="Bravo")*(D2:D17))+SUMPRODUCT((B2:B17="USA")*(C2:C17="Bravo")*(D2:D17))

Andrew beat me, no surprise ...heh
 
Upvote 0
My table is below. I want to basically do a sum if with multiple criteria, but multiple criteria in multiple columns. I know how to do multiple criteria in a single column which is done like this "=SUM(SUMIFS(C2:C17,A2:A17,{"Europe","USA"},B2:B17,"Alpha"))"... but I'm trying to take it one step further and add in "Bravo" as well.

If this were a math function I want to do basically this. (X+Y)*(A+B), which is four functions. X*A, X*B, Y*A and Y*B. I need a formula that can sum the results using the multiple criteria. (Europe+USA)*(Alpha+Bravo).

Sum the criteria (Europe*Alpha, Europe* Bravo, USA*Alpha, USA*Bravo).

I been working on this for some time, it's quite stressful. I know the geniuses on here can help me resolve this. If this is confusing, please let me know and I will try to simply my needs better. Thanks in advance!



[TABLE="width: 192"]
<tbody>[TR]
[TD="width: 64"]Region
[/TD]
[TD="width: 64"]Team
[/TD]
[TD="width: 64"]Sales
[/TD]
[/TR]
[TR]
[TD]ASIA
[/TD]
[TD]Alpha
[/TD]
[TD="align: right"]30
[/TD]
[/TR]
[TR]
[TD]ASIA
[/TD]
[TD]Bravo
[/TD]
[TD="align: right"]40
[/TD]
[/TR]
[TR]
[TD]ASIA
[/TD]
[TD]Alpha
[/TD]
[TD="align: right"]110
[/TD]
[/TR]
[TR]
[TD]ASIA
[/TD]
[TD]Bravo
[/TD]
[TD="align: right"]120
[/TD]
[/TR]
[TR]
[TD]Brazil
[/TD]
[TD]Alpha
[/TD]
[TD="align: right"]70
[/TD]
[/TR]
[TR]
[TD]Brazil
[/TD]
[TD]Bravo
[/TD]
[TD="align: right"]80
[/TD]
[/TR]
[TR]
[TD]Brazil
[/TD]
[TD]Alpha
[/TD]
[TD="align: right"]150
[/TD]
[/TR]
[TR]
[TD]Brazil
[/TD]
[TD]Bravo
[/TD]
[TD="align: right"]160
[/TD]
[/TR]
[TR]
[TD]Europe
[/TD]
[TD]Alpha
[/TD]
[TD="align: right"]10
[/TD]
[/TR]
[TR]
[TD]Europe
[/TD]
[TD]Bravo
[/TD]
[TD="align: right"]20
[/TD]
[/TR]
[TR]
[TD]Europe
[/TD]
[TD]Alpha
[/TD]
[TD="align: right"]90
[/TD]
[/TR]
[TR]
[TD]Europe
[/TD]
[TD]Bravo
[/TD]
[TD="align: right"]100
[/TD]
[/TR]
[TR]
[TD]USA
[/TD]
[TD]Alpha
[/TD]
[TD="align: right"]50
[/TD]
[/TR]
[TR]
[TD]USA
[/TD]
[TD]Bravo
[/TD]
[TD="align: right"]60
[/TD]
[/TR]
[TR]
[TD]USA
[/TD]
[TD]Alpha
[/TD]
[TD="align: right"]130
[/TD]
[/TR]
[TR]
[TD]USA
[/TD]
[TD]Bravo
[/TD]
[TD="align: right"]140
[/TD]
[/TR]
</tbody>[/TABLE]

Using SUMIFS requires re-arrangement...

=SUM(SUMIFS(C2:C17,A2:A17,{"Europe","USA"},B2:B17,{"Alpha";"Bravo"}))

Comma with countries, semi-colon with tags.
 
Upvote 0
...wait, What if I add a third column and the criteria is just "South"?

[TABLE="width: 256"]
<colgroup><col width="64" span="4" style="width:48pt"> </colgroup><tbody>[TR]
[TD="width: 64"]Region[/TD]
[TD="width: 64"]Team[/TD]
[TD="width: 64"]Sub Region[/TD]
[TD="width: 64"]Sales[/TD]
[/TR]
[TR]
[TD]ASIA[/TD]
[TD]Alpha[/TD]
[TD]North[/TD]
[TD="align: right"]30[/TD]
[/TR]
[TR]
[TD]ASIA[/TD]
[TD]Bravo[/TD]
[TD]South[/TD]
[TD="align: right"]40[/TD]
[/TR]
[TR]
[TD]ASIA[/TD]
[TD]Alpha[/TD]
[TD]South[/TD]
[TD="align: right"]110[/TD]
[/TR]
[TR]
[TD]ASIA[/TD]
[TD]Bravo[/TD]
[TD]North[/TD]
[TD="align: right"]120[/TD]
[/TR]
[TR]
[TD]Brazil[/TD]
[TD]Alpha[/TD]
[TD]North[/TD]
[TD="align: right"]70[/TD]
[/TR]
[TR]
[TD]Brazil[/TD]
[TD]Bravo[/TD]
[TD]South[/TD]
[TD="align: right"]80[/TD]
[/TR]
[TR]
[TD]Brazil[/TD]
[TD]Alpha[/TD]
[TD]South[/TD]
[TD="align: right"]150[/TD]
[/TR]
[TR]
[TD]Brazil[/TD]
[TD]Bravo[/TD]
[TD]North[/TD]
[TD="align: right"]160[/TD]
[/TR]
[TR]
[TD]Europe[/TD]
[TD]Alpha[/TD]
[TD]North[/TD]
[TD="align: right"]10[/TD]
[/TR]
[TR]
[TD]Europe[/TD]
[TD]Bravo[/TD]
[TD]South[/TD]
[TD="align: right"]20[/TD]
[/TR]
[TR]
[TD]Europe[/TD]
[TD]Alpha[/TD]
[TD]South[/TD]
[TD="align: right"]90[/TD]
[/TR]
[TR]
[TD]Europe[/TD]
[TD]Charlie[/TD]
[TD]North[/TD]
[TD="align: right"]100[/TD]
[/TR]
[TR]
[TD]USA[/TD]
[TD]Alpha[/TD]
[TD]North[/TD]
[TD="align: right"]50[/TD]
[/TR]
[TR]
[TD]USA[/TD]
[TD]Charlie[/TD]
[TD]South[/TD]
[TD="align: right"]60[/TD]
[/TR]
[TR]
[TD]USA[/TD]
[TD]Alpha[/TD]
[TD]South[/TD]
[TD="align: right"]130[/TD]
[/TR]
[TR]
[TD]USA[/TD]
[TD]Bravo[/TD]
[TD]North[/TD]
[TD="align: right"]140[/TD]
[/TR]
</tbody>[/TABLE]
 
Upvote 0
...wait, What if I add a third column and the criteria is just "South"?

[TABLE="width: 256"]
<tbody>[TR]
[TD="width: 64"]Region
[/TD]
[TD="width: 64"]Team
[/TD]
[TD="width: 64"]Sub Region
[/TD]
[TD="width: 64"]Sales
[/TD]
[/TR]
[TR]
[TD]ASIA
[/TD]
[TD]Alpha
[/TD]
[TD]North
[/TD]
[TD="align: right"]30
[/TD]
[/TR]
[TR]
[TD]ASIA
[/TD]
[TD]Bravo
[/TD]
[TD]South
[/TD]
[TD="align: right"]40
[/TD]
[/TR]
[TR]
[TD]ASIA
[/TD]
[TD]Alpha
[/TD]
[TD]South
[/TD]
[TD="align: right"]110
[/TD]
[/TR]
[TR]
[TD]ASIA
[/TD]
[TD]Bravo
[/TD]
[TD]North
[/TD]
[TD="align: right"]120
[/TD]
[/TR]
[TR]
[TD]Brazil
[/TD]
[TD]Alpha
[/TD]
[TD]North
[/TD]
[TD="align: right"]70
[/TD]
[/TR]
[TR]
[TD]Brazil
[/TD]
[TD]Bravo
[/TD]
[TD]South
[/TD]
[TD="align: right"]80
[/TD]
[/TR]
[TR]
[TD]Brazil
[/TD]
[TD]Alpha
[/TD]
[TD]South
[/TD]
[TD="align: right"]150
[/TD]
[/TR]
[TR]
[TD]Brazil
[/TD]
[TD]Bravo
[/TD]
[TD]North
[/TD]
[TD="align: right"]160
[/TD]
[/TR]
[TR]
[TD]Europe
[/TD]
[TD]Alpha
[/TD]
[TD]North
[/TD]
[TD="align: right"]10
[/TD]
[/TR]
[TR]
[TD]Europe
[/TD]
[TD]Bravo
[/TD]
[TD]South
[/TD]
[TD="align: right"]20
[/TD]
[/TR]
[TR]
[TD]Europe
[/TD]
[TD]Alpha
[/TD]
[TD]South
[/TD]
[TD="align: right"]90
[/TD]
[/TR]
[TR]
[TD]Europe
[/TD]
[TD]Charlie
[/TD]
[TD]North
[/TD]
[TD="align: right"]100
[/TD]
[/TR]
[TR]
[TD]USA
[/TD]
[TD]Alpha
[/TD]
[TD]North
[/TD]
[TD="align: right"]50
[/TD]
[/TR]
[TR]
[TD]USA
[/TD]
[TD]Charlie
[/TD]
[TD]South
[/TD]
[TD="align: right"]60
[/TD]
[/TR]
[TR]
[TD]USA
[/TD]
[TD]Alpha
[/TD]
[TD]South
[/TD]
[TD="align: right"]130
[/TD]
[/TR]
[TR]
[TD]USA
[/TD]
[TD]Bravo
[/TD]
[TD]North
[/TD]
[TD="align: right"]140
[/TD]
[/TR]
</tbody>[/TABLE]

Didn't you try?...

=SUM(SUMIFS(D2:D17,A2:A17,{"Europe","USA"},B2:B17,{"Alpha";"Bravo"},C2:C17,"South"))

considering the changes in the lay-out.
 
Upvote 0
That doesn't work. When you use multiple arrays they work as a matching function.

=SUM(SUMIFS(D2:D17,A2:A17,{"Europe","USA"},B2:B17,{"Alpha";"Bravo"},C2:C17,"South"))

=(Europe*Alpha*South)+(USA*Bravo)

I need a formula that will go.

=(Europe*Alpha*South)+(Europe*Bravo*South)+(USA*Alpha*South)+(USA*Bravo*South*)

please excuse the bold, it turned on and I can't turn it off.
 
Upvote 0
Like this?

=SUMPRODUCT(((A2:A17="Europe")+(A2:A17="USA")),((B2:B17="Alpha")+(B2:B17="Bravo")),--(C2:C17="South"),D2:D17)
 
Upvote 0

Forum statistics

Threads
1,223,895
Messages
6,175,257
Members
452,625
Latest member
saadat28

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