SUMIF multiple columns

joe-carter

New Member
Joined
Jul 2, 2004
Messages
34
I'm trying to sumif for a range. Pretend below is an exceil file with A1=1, and D4=A. I wrote "=SUMIF(D1:D4,"A",A1:C4)". The answer would be "7", or 1+2+2 in the first "A" row plus 1+0+1 in the second "A" row. It worked for a while, but now it won't. The problem is A1:C4, it seems the SUMIF command wants this to be A1:A4. I could make a big sumif command "=SUMIF(D1:D4,"A",A1:A4)+SUMIF(D1:D4,"A",B1:B4)+SUMIF(D1:D4,"A",C1:C4)", but would rather be clever.

1, 2, 2, A
2, 2, 1, B
1, 1, 1, C
1, 0, 1, A

Thanks,

Joe
 

Excel Facts

Pivot Table Drill Down
Double-click any number in a pivot table to create a new report showing all detail rows that make up that number
I'm trying to sumif for a range. Pretend below is an exceil file with A1=1, and D4=A. I wrote "=SUMIF(D1:D4,"A",A1:C4)". The answer would be "7", or 1+2+2 in the first "A" row plus 1+0+1 in the second "A" row. It worked for a while, but now it won't. The problem is A1:C4, it seems the SUMIF command wants this to be A1:A4. I could make a big sumif command "=SUMIF(D1:D4,"A",A1:A4)+SUMIF(D1:D4,"A",B1:B4)+SUMIF(D1:D4,"A",C1:C4)", but would rather be clever.

1, 2, 2, A
2, 2, 1, B
1, 1, 1, C
1, 0, 1, A

Thanks,

Joe
Switch to...

Control+shift+enter, not just enter:

=SUM(IF($D$1:$D$4="A",$A$1:$C$4))

Note to Marcelo. The star syntax to over vector/matrix multiplications will run into problems if the matrix reference houses blanks or other text.
 
Upvote 0
=SUMPRODUCT($C$3:$F$65,($N$3:$N$65="A")) is what I typed in and it worked for a moment, but now it won't, just like the SUMIF.

I actually have (8) columns to add in this matter. I guess the better question is, how can I be more concise with the following formula:
=SUMIF($N$3:$N$65,K67,$C$3:$C$65)+SUMIF($N$3:$N$65,K67,$D$3:$D$65)
+SUMIF($N$3:$N$65,K67,$E$3:$E$65)+SUMIF($N$3:$N$65,K67,$F$3:$F$65)
+SUMIF($N$3:$N$65,K67,$V$3:$V$65)+SUMIF($N$3:$N$65,K67,$W$3:$W$65)
+SUMIF($N$3:$N$65,K67,$X$3:$X$65)+SUMIF($N$3:$N$65,K67,$Y$3:$Y$65).

Notice my (8) columns of C, D, E, F, then V, W, X, Y. Since the criteria is the same (wherever $N$3:$N$65 equals K67), I should be able to create a more concise formula.

joe
 
Upvote 0
=SUMPRODUCT($C$3:$F$65,($N$3:$N$65="A")) is what I typed in and it worked for a moment, but now it won't, just like the SUMIF.

Try this

=SUMPRODUCT($C$3:$F$65*($N$3:$N$65="A"))

M.
 
Upvote 0
Aladin
Note to Marcelo. The star syntax to over vector/matrix multiplications will run into problems if the matrix reference houses blanks or other text.

You are right, as usual. Tks for for the advice.
(i had not seen it when i made my last post)

M.
 
Upvote 0
=SUMPRODUCT($C$3:$F$65,($N$3:$N$65="A")) is what I typed in and it worked for a moment, but now it won't, just like the SUMIF.

I actually have (8) columns to add in this matter. I guess the better question is, how can I be more concise with the following formula:
=SUMIF($N$3:$N$65,K67,$C$3:$C$65)+SUMIF($N$3:$N$65,K67,$D$3:$D$65)
+SUMIF($N$3:$N$65,K67,$E$3:$E$65)+SUMIF($N$3:$N$65,K67,$F$3:$F$65)
+SUMIF($N$3:$N$65,K67,$V$3:$V$65)+SUMIF($N$3:$N$65,K67,$W$3:$W$65)
+SUMIF($N$3:$N$65,K67,$X$3:$X$65)+SUMIF($N$3:$N$65,K67,$Y$3:$Y$65).

Notice my (8) columns of C, D, E, F, then V, W, X, Y. Since the criteria is the same (wherever $N$3:$N$65 equals K67), I should be able to create a more concise formula.

joe
Try this array formula**:

=SUM(IF(N3:N65=K67,C3:F65),IF(N3:N65=K67,V3:Y65))

** array formulas need to be entered using the key
combination of CTRL,SHIFT,ENTER (not just ENTER).
Hold down both the CTRL key and the SHIFT key
then hit ENTER.
 
Upvote 0
both worked,
{=SUM(IF($N$3:$N$65=K67,$C$3:$F$65))+SUM(IF($N$3:$N$65=K67,$V$3:$Y$65))}
AND
{=SUM(IF($N$3:$N$65=K67,$C$3:$F$65),IF(N3:N65=K67,$V$3:$Y$65))

I went with the second one. It will hopefully get me thinking about using array formulas more.

Thanks!
 
Upvote 0
both worked,
{=SUM(IF($N$3:$N$65=K67,$C$3:$F$65))+SUM(IF($N$3:$N$65=K67,$V$3:$Y$65))}
AND
{=SUM(IF($N$3:$N$65=K67,$C$3:$F$65),IF(N3:N65=K67,$V$3:$Y$65))

I went with the second one. It will hopefully get me thinking about using array formulas more.

Thanks!
You're welcome. Thanks for the feedback! :cool:
 
Upvote 0
2r3v9qw.png


In cell B10 - B12 I am trying to add the data from the table above A1:E10. In other words in cell B10 I am trying to sum the data in cells B2 to E2, with the criteria of "Jan" and "a". In all the videos on YouTube I only saw sumifs being used for columns with different criteria, here we have the same criteria. I know you could us a simple "sum" but it is very manual especially if the data is on a different worksheet and it span 100+ columns. I hope the question makes sense. Thank you.
 
Upvote 0

Forum statistics

Threads
1,224,524
Messages
6,179,308
Members
452,904
Latest member
CodeMasterX

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