Count cells that do not contain errors

=SUMPRODUCT(--NOT(ISERROR(range)))
To count the number of cells that do not contain errors, you can use the ISERROR and NOT functions, wrapped in the SUMPRODUCT function. In the example shown, the formula in E5 is:
=SUMPRODUCT(--NOT(ISERROR(B5:B14)))
In this example, the goal is to count the number of cells in a range that do not contain errors.
Working from the inside out, we first use the ISERROR function on the entire range:
ISERROR(B5:B14) // check all 10 cells
Since there are ten cells in the range B5:B14, ISERROR returns an array with ten results like this:
{FALSE;TRUE;FALSE;FALSE;FALSE;TRUE;FALSE;FALSE;FALSE;TRUE}
Here, each TRUE value indicates a cell value that is an error. Since the goal is to count cells that do not contain errors, we reverse these results with the NOT function:
NOT({FALSE;TRUE;FALSE;FALSE;FALSE;TRUE;FALSE;FALSE;FALSE;TRUE})
which returns:
{TRUE;FALSE;TRUE;TRUE;TRUE;FALSE;TRUE;TRUE;TRUE;FALSE}
Notice that each TRUE value now corresponds to a cell that does not contain an error. 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 (--):
--{TRUE;FALSE;TRUE;TRUE;TRUE;FALSE;TRUE;TRUE;TRUE;FALSE}
The resulting array looks like this:
{1;0;1;1;1;0;1;1;1;0}
Finally, SUMPRODUCT sums the items in this array and returns the total, which in the example is the number 3:
=SUMPRODUCT({1;0;1;1;1;0;1;1;1;0}) // returns 7
ISERR function
Like the ISERROR function, the ISERR function returns TRUE when a value is an error. The difference is that ISERR ignores #N/A errors. If you want to count cells that do not contain errors, and ignore #N/A errors, you can substitute ISERR for ISERROR:
=SUMPRODUCT(--NOT(ISERR(B5:B14))) // ignore #N/A
SUM option
You can also use the SUM function to count errors. The structure of the formula is the same:
Note: this is an array formula and must be entered with control + shift + enter, except in Excel 365.
Download 100+ Important Excel Functions
Get over 100 Excel Functions you should know in one handy PDF.