How to use a logical AND or OR in a SUM+IF statement in Excel (267982)
The information in this article applies to:
- Microsoft Excel 2002
- Microsoft Excel 2000
- Microsoft Excel 97 for Windows
- Microsoft Excel 2004 for Mac
- Microsoft Excel X for Mac
- Microsoft Excel 2001 for Mac
- Microsoft Excel 98 Macintosh Edition
- Microsoft Office Excel 2003
This article was previously published under Q267982 SUMMARY
In Microsoft Excel, when you use the logical functions AND and/or OR inside a SUM+IF statement to test a range for more than one condition, it may not work as expected. A nested IF statement provides this functionality; however, this article discusses a second, easier method that uses the following formulas.
For AND Conditions
=SUM(IF(Test1*Test2*...*Testn))
For OR Conditions
=SUM(IF(Test1+Test2+...+Testn))
MORE INFORMATION
Use a SUM+IF statement to count the number of cells in a range
that pass a given test or to sum those values in a range for which
corresponding values in another (or the same) range meet the specified
criteria. This behaves similarly to the DSUM function in Microsoft Excel.
Example
This example counts the number of values in the range A1:A10 that fall
between 1 and 10, inclusively.
To accomplish this, you can use the following nested IF statement:
=SUM(IF(A1:A10>=1,IF(A1:A10<=10,1,0)))
The following method also works and is much easier to read if you are conducting multiple tests:
=SUM(IF((A1:A10>=1)*(A1:A10<=10),1,0))
The following method counts the number of dates that fall between two given dates:
=SUM(IF((A1:A10>=DATEVALUE("1/10/99"))*(A1:A10<=DATEVALUE("2/10/99")),1,0))
Notes- You must enter these formulas as array formulas by pressing
CTRL+SHIFT+ENTER simultaneously. On the Macintosh, press COMMAND+RETURN instead.
- Arrays cannot refer to entire columns.
With this method, you are multiplying the results of one logical test by
another logical test to return TRUEs and FALSEs to the SUM function. You can equate these to:
TRUE*TRUE=1
TRUE*FALSE=0
FALSE*TRUE=0
FALSE*FALSE=0
The method shown above counts the number of cells in the range A1:A10
for which both tests evaluate to TRUE. To sum values in corresponding
cells (for example, B1:B10), modify the formula as shown below:
=SUM(IF((A1:A10>=1)*(A1:A10<=10),B1:B10,0))
You can implement an OR in a SUM+IF statement similarly. To do this,
modify the formula shown above by replacing the multiplication sign (*)
with a plus sign (+). This gives the following generic formula:
=SUM(IF((Test1)+(Test2)+...+(Testn),1,0))
REFERENCESFor more information about how to calculate a value based on a condition, click Microsoft Excel Help on the Help menu, type about calculating a value based on a condition in the Office Assistant or the Answer Wizard, and then click Search to view the topic.
Modification Type: | Major | Last Reviewed: | 1/21/2005 |
---|
Keywords: | kbhowto kbualink97 KB267982 |
---|
|