Sumifs with or condition over multiple columns

quiqueperez

New Member
Joined
Sep 10, 2014
Messages
12
Hi,

I'm struggling to write a formula to sum the values in column A based on a number of conditions, including one that applies over multiple columns.

Using the following example, I would need to add the values in column A if condition 1 = Australia and the value in at least one of the areas is greater than zero.

In the current example the result woud be 55 (row3 + row4)


VALUES TO ADDCONDITION 1AREA 1AREA 2AREA 3
56US102
23AUSTRALIA010
32AUSTRALIA112
14AUSTRALIA000

<tbody>
</tbody>


The formula I'm thinking of is something like this, but I don't know how to formulate it,

SUMIFS(VALUES TO ADD, CONDITION 1, AUSTRALIA, SUM(AREA 1, AREA 2, AREA 3), ">0")

Any would be very much appreciated.

Cheers,
Enrique
 

Excel Facts

How can you turn a range sideways?
Copy the range. Select a blank cell. Right-click, Paste Special, then choose Transpose.
You can add a helper column to check if the SUM from the three areas is greater than 3 and use those values in a formula

See 2 sample formulas in H2 and I2


Excel 2010
ABCDEFGHI
1VALUES TO ADDCONDITION 1AREA 1AREA 2AREA 3AREA>0
256US102TRUEAUSTRALIA5555
323AUSTRALIA010TRUE
432AUSTRALIA112TRUE
514AUSTRALIA000FALSE
Sheet1
Cell Formulas
RangeFormula
F2=SUM(C2:E2)>0
H2=SUMPRODUCT((A2:A5)*(B2:B5=G2)*(F2:F5))
I2{=SUM(IF(B2:B5=G2,IF(F2:F5=TRUE,A2:A5)))}
Press CTRL+SHIFT+ENTER to enter array formulas.
 
Upvote 0
if you don't want to average, you can also use just the sumformula.

f2=sum(c2:e2) and drag down.

Then you can use the formula of momentman.

you can also use a pivot talbe to get the result.
 
Upvote 0
No idea why Momentman does not invoke a SUMIFS formula after creating the F range with =SUM(C2:E2)>0 as in:
Rich (BB code):
=SUMIFS(A2:A5,B2:B5,"AUSTRALIA",F2:F5)
If you don't want create an additional range, try:

Control+shift+enter, not just enter:
Rich (BB code):
=SUM(IF(MMULT($C$2:$E$5,TRANSPOSE(COLUMN($C$2:$E$5)^0))>0,
  IF($B$2:$B$5="AUSTRALIA",$A$2:$A$5)))
 
Upvote 0
Hi,
Many thansk for your responses.
But, would it be posible to get to the same result without adding any columns to the origianal file??
(the problem is that the original file is an standard report for another software and would be much easier if I didn't have to manipulate it)
Cheers,
Enrique
 
Upvote 0
Did you confirm the formula with CONTROL+SHIFT+ENTER, not just ENTER? In other words, enter the formula in the cell, press down on the CONTROL key, and while the CONTROL key is pressed down, press down on both the SHIFT and ENTER keys. If done correctly, Excel will automatically place curly braces {...} around the formula. Does this help?
 
Upvote 0
Thanks for your help!
I think that the error was that I was including in the cell ranges the column headings.
It seems to work now!
 
Upvote 0

Forum statistics

Threads
1,214,653
Messages
6,120,750
Members
448,989
Latest member
mariah3

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