How to count blank cells
The image above shows the COUNTBLANK function counting empty cells in cell range B3:B14. Note that the COUNTBLANK function ignores error values, most Excel functions don't.
Formula in cell D3:
What will this formula return if there was a space character in cell B7? The cell is not empty anymore, however, it looks empty. See image below.
The following formula counts blank cells even if the cell contains one or more space characters.
Array formula in cell D5:
To enter an array formula, type the formula in a cell then press and hold CTRL + SHIFT simultaneously, now press Enter once. Release all keys.
The formula bar now shows the formula with a beginning and ending curly bracket telling you that you entered the formula successfully. Don't enter the curly brackets yourself.
Explaining formula in cell D5
Step 1 - Remove leading and trailing space characters
The TRIM function deletes leading and trailing space characters from a cell value, however, here I am using a cell range so we need to enter this formula as an array formula.
TRIM(B3:B14)
becomes
TRIM({"ZF";"";"5";"T5";" ";#N/A;"SK";"JK";"";"DP";"3";#DIV/0!})
and returns
{"ZF";"";"5";"T5";"";#N/A;"SK";"JK";"";"DP";"3";#DIV/0!}
Step 2 - Convert error values to a valid value
Also, the TRIM function doesn't ignore error values, we need to trap those error values before counting them and the IFERROR function allows you to do that.
becomes
IFERROR({"ZF";"";"5";"T5";"";#N/A;"SK";"JK";"";"DP";"3";#DIV/0!},"A")
and returns {"ZF";"";"5";"T5";"";#N/A;"SK";"JK";"";"DP";"3";#DIV/0!}.
I have entered the array in column A.
Step 3 - Compare each value in the array to nothing
The equal sign lets you compare the values in the array to a given condition, in this case "" is nothing.
becomes
{"ZF";"";"5";"T5";"";"A";"SK";"JK";"";"DP";"3";"A"}=""
and returns {FALSE; TRUE; FALSE; FALSE; TRUE; FALSE; FALSE; FALSE; TRUE; FALSE; FALSE; FALSE}.
I have entered the array in column A.
Step 4 - Convert boolean values
The SUM function can't add boolean values in an array, we need to convert them. TRUE becomes 1 and FALSE becomes 0 (zero).
(IFERROR(TRIM(B3:B14),"A")="")*1
becomes
({FALSE; TRUE; FALSE; FALSE; TRUE; FALSE; FALSE; FALSE; TRUE; FALSE; FALSE; FALSE})*1
and returns {0; 1; 0; 0; 1; 0; 0; 0; 1; 0; 0; 0}.
I have entered the array in column A.
Step 5 - Sum values
SUM((IFERROR(TRIM(B3:B14),"A")="")*1)
becomes
SUM({0; 1; 0; 0; 1; 0; 0; 0; 1; 0; 0; 0}) and returns 3 in cell D5.
Count category
Question: How do I count how many times a word exists in a range of cells? It does not have […]
Table of Contents Count a specific text string in a cell Count text string in a range (case sensitive) Count […]
Question: How do I count the number of times a text string exists in a column? The text string may […]
The formula in cell B17 counts rows in cell range B3:D17 when at least one cell per row contains data. […]
The COUNTIF function is very capable of counting non-empty values, I will show you how in this article. Excel can […]
The formula in cell F9 counts the number of cells in column B (Values1) that are equal to any of the […]
Table of Contents Count cells with text Count cells with text excluding cells containing a space character Count text values […]
The array formula in cell F3 counts cells in column B that contains at least one of the values in […]
The formula in cell B6 counts how many times the string (D3) is found in a cell value (B3) even […]
This article demonstrates an array formula that counts how many times multiple text strings exist in a cell range. The […]
Functions in this article
More than 1300 Excel formulas
Excel formula categories
Excel categories
Leave a Reply
How to comment
How to add a formula to your comment
<code>Insert your formula here.</code>
Convert less than and larger than signs
Use html character entities instead of less than and larger than signs.
< becomes < and > becomes >
How to add VBA code to your comment
[vb 1="vbnet" language=","]
Put your VBA code here.
[/vb]
How to add a picture to your comment:
Upload picture to postimage.org or imgur
Paste image link to your comment.