Getting a Conditional Count of Cells Containing Values

Written by Allen Wyatt (last updated October 22, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021


The formula =SUMIF(B1:B100,"Current",D1:D100) provides the sum of the values in column D, provided the corresponding cell in column B contains the text "Current". What Kenneth actually needs, though, is a count of the values in column D when column B contains "Current". (The count of values in D may well be different than the number of instances of "Current" in B.) He wishes it was as simple as changing SUMIF to COUNTIF, but that produces an error.

The reason the error occurs is because SUMIF requires three parameters and COUNTIF requires only two. Thus, if you simply replace SUMIF with COUNTIF, then you'll get an error. Instead, you could use COUNTIF in this way:

=COUNTIF(B1:B100,"Current")

This will not give you an error, but it also won't give you a correct answer. Kenneth wants a count of the number of cells containing values in the range D1:D100, but only if the corresponding cell in column B contains the text "Current." The COUNTIF formula doesn't even take column D into effect; it only counts the number of cells in the range B1:B100 that contain the word "Current."

The solution is to use the COUNTIFS function, instead. This function allows you to check multiple conditions in order to derive a count. In this case, the following version would work:

=COUNTIFS(B1:B100,"current",D1:D100,">0")

This formula counts the number of values in D1:D100 that are greater than zero. (Well, it also only counts them if B1:B100 contains "current.") This works because empty cells or cells that contain text are considered by COUNTIFS to be equivalent to 0. Note, as well, that the function is case-insensitive when it comes to matching: "current" will also match "Current" or any combination of uppercase and lowercase letters in the word.

If your cells might contain negative values, then you should try this variation, instead:

=COUNTIFS(B1:B100,"current",D1:D100,"<>")

The drawback is that this method also includes in the count any cells that contain text.

You could also use the following formula:

=SUMPRODUCT(--(B1:B100="current"),--(D1:D100<>""))

Again, this one includes text values in the count. If you want to ignore the text values, then this variation works great:

=SUMPRODUCT(--(B1:B100="current"),--ISNUMBER(D1:D100))

The following formula can also be used, provided you enter it as an array formula (press Ctrl+Shift+Enter):

=SUM((B1:B100="current")*ISNUMBER(D1:D100))

There are also other ways you could derive the total you need. One method would be to use the DCOUNT function (which counts based upon multiple criteria), but that approach requires more setup than the formulas already described.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13433) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Copying Found Items to a New Document

Word allows you to use its searching capabilities to easily find multiple items in a document. What if you want to copy ...

Discover More

Printing a List of Custom Styles

You can add any number of styles to your document in order to define how you want your text to appear. If you later want ...

Discover More

Getting Rid of Negative Zero Amounts

Have you ever seen a worksheet in which some zero values have a negative sign in front of them? There's a reason for ...

Discover More

Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!

More ExcelTips (ribbon)

Calculating Monthly Interest Charges

Trying to calculate how much people owe you? If you charge interest or service charges on past-due accounts, there are a ...

Discover More

Counting Only Money Winners

If a series of cells contain the amount of money won by individuals, you may want to count the number of individuals who ...

Discover More

First Value Less Than or Equal to 100

If you need to evaluate a row of values to meet specific criteria, then you'll appreciate the discussion in this tip. It ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is five more than 3?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


This Site

Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.