Double Condition (If w/nested sumif)

schmadly

Board Regular
Joined
Mar 29, 2006
Messages
79
The Issue: I need a formula that looks for an "x" in cell value I21. If it finds an "x", then I need it to see if there is either a "y" or a "p" in the cell directly above. If there is a "y" or a "p", then I need it to find the number above the "y" or the "p" and sum all of those number in one cell.

What I have tried: An IF with a SUMIF nested inside, but it would only sum ALL numbers, I didn't get it to look for double criteria (both the "x" and the "y"/"p" above the "x".

Example: The answer should be "2" (the first column has a "y" and an "x" so it finds the "1" above them - the second column has a "p" and an "x" so it finds that "1" above them and then adds the two 1's together). Make sense?



1 1 2 2 1
Y P Y N P
x x
 

Excel Facts

Who is Mr Spreadsheet?
Author John Walkenbach was Mr Spreadsheet until his retirement in June 2019.

Brian from Maui

MrExcel MVP
Joined
Feb 16, 2002
Messages
8,458
Per your example, try;

=SUMPRODUCT(--(A3:F3="x"),--(ISNUMBER(MATCH(A2:F2,{"p","y"},0))),A1:F1)
 

schmadly

Board Regular
Joined
Mar 29, 2006
Messages
79
Thank you very much

It works! Thanks a bunch - I had forgotten about SUMPRODUCT. I know about MATCH, but what is the purpose of the --ISNUMBER?
 

Brian from Maui

MrExcel MVP
Joined
Feb 16, 2002
Messages
8,458
Re: Thank you very much

It works! Thanks a bunch - I had forgotten about SUMPRODUCT. I know about MATCH, but what is the purpose of the --ISNUMBER?

My understanding (corrections welcome) is, ISNUMBER tests whether a match is found and does not return the #N/A error if there is no match.
 

Forum statistics

Threads
1,136,649
Messages
5,676,990
Members
419,667
Latest member
MegEri

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
Top