Exceljet

Quick, clean, and to the point

Count cells that do not contain errors

Excel formula: Count cells that do not contain errors
Generic formula 
=SUMPRODUCT(--NOT(ISERR(rng)))
Summary 

To count the number of cells that contain errors, you can use the ISERR and NOT functions, wrapped in the SUMPRODUCT function. In the example, the active cell contains this formula:

=SUMPRODUCT(--NOT(ISERR(B4:B8)))
Explanation 

In the generic form of the formula (above) rng represents the range in which you'd like to count cells with no errors.

SUMPRODUCT accepts one or more arrays and calculates the sum of products of corresponding numbers. If only one array is supplied, it just sums the items in the array.

Working from the inside out, we first hand off the range to ISERR:

ISERR(B4:B8)

The ISERR function is evaluated for each cell in B4:B8. Because give ISERR five values, we get back five results, in an array like this:

{TRUE;FALSE;TRUE;FALSE;FALSE} // result from ISERR

Next, we use the NOT function to "reverse" these values. The result is another array like this:

{FALSE;TRUE;FALSE;TRUE;TRUE} // result from NOT

This array is now in the correct format – TRUE values indicate cells without errors, FALSE values indicate cells with errors.

Since SUMPRODUCT only works with numeric data, the next step is to convert the TRUE and FALSE values to their numeric equivalents, 1 and 0. We do this with a double negative (--). The resulting array looks like this:

{0;1;0;1;1}

Finally, SUMPRODUCT sums the items in this array and returns the total, which in the example is the number 3:

=SUMPRODUCT({0;1;0;1;1}) // returns 3

SUM option

You can also use the SUM function to count errors in an array formula. The structure of the formula is the same:

{=SUM(--NOT(ISERR(B4:B8)))}

Note: This is an array formula and must be entered with control + shift + enter, except in Excel 365.

Author 
Dave Bruns

Excel Formula Training

Formulas are the key to getting things done in Excel. In this accelerated training, you'll learn how to use formulas to manipulate text, work with dates and times, lookup values with VLOOKUP and INDEX & MATCH, count and sum with criteria, dynamically rank values, and create dynamic ranges. You'll also learn how to troubleshoot, trace errors, and fix problems. Instant access. See details here.