How to use the COUNTBLANK function
What is the COUNTBLANK Function?
The COUNTBLANK function counts empty or blank cells in a range.
Table of Contents
1. Syntax
COUNTBLANK(value1, [value2], ...)
2. Arguments
value1 | Required. A cell reference to a range for which you want to count empty cells. |
[value2] | Optional. Up to 254 additional arguments like the one above. |
The COUNTBLANK function counts errors as not empty.
3. Example
The picture above demonstrates the COUNTBLANK function entered in cell F3, it counts blank cells meaning empty cells. The evaluated range is C3:C10, two of the cells contains formulas, three cells seem to be empty but only one is in fact empty. Column B shows the count of empty cells in cell C3:C10-
- Cell C3 contains a text value "A", this cell is not empty. There is no formula in that cell so cell D3 shows nothing.
- Cell C4 contains ="" which is a formula that returns nothing. Cell D4 shows the formula. Cell B3 shows one 1 meaning the COUNTBLANK function considers this cell empty.
- Cell C5 contains a number, this cell is not empty. D5 shows nothing, no formula is in cell C5.
- Cell C6 is empty.
- Cell C7 contains a space character.
- Cell C8 contains boolean value TRUE, this cell is not empty.
- Cell C9 contains the #DIV/0! error, this cell is not empty. Cell D9 shows the formula that returns this error.
- Cell C10 contains test string "Text", this cell is not empty.
Tip! Use the TRIM function to remove space characters before using the COUNTBLANK function. This will count cells as empty if they only contain a space character if this is what you want.
The formula in cell F3 counts two empty cells in cell range C3:C10. Note, there is also one error value meaning the COUNTBLANK function works with error values as well.
Formula in cell F3:
Explaining formula
COUNTBLANK(C3:C10)
becomes
COUNTBLANK({"A";"";44;0;" ";TRUE;#DIV/0!;"Text"})
and returns 2.
Cell C7 is not empty, it contains a space character. Cell C4 contains a formula, however, the output is nothing. The COUNTBLANK function counts cell C4 as empty.
4. Count blanks - arrays and other functions
The COUNTBLANK function doesn't let you use hard-coded arrays in the range argument. This example shows that you can't use hard-coded arrays in the COUNTBLANK function, a dialog box appears telling you there is a problem with the formula.
Formula in cell C3:
The COUNTBLANK function does not allow you to use the IF function in the range argument at all. The image above shows a data table in cell range B3:C11. The fomrula in cell F3 tries to use a condition before evaluating if cells are empty or not.
The image above shows what happens if you try to use the IF function in the range argument. The formula below returns #VALUE! errors.
There is however a workaround presented in section 5 below.
5. Count blanks based on a condition
This example demonstrates how to count empty cells based on a condition. Cell range B3:C11 contains a data table, it has the following header names: "Item" and " Amounts".
Item | Amounts |
Pen | |
Pencil | 7 |
Clip | 45 |
Pen | 31 |
Clip | |
Pencil | 37 |
Pen | 98 |
Clip | |
Clip | 6 |
The formula in cell F3 filters empty cell values from C3:C11 based on the condition specified in cell E3. If the cell in cell range B3:B11 matches the condition then the SUM function adds those cells to the total count of empty cells.
Formula in cell F3:
For example, cells B5, B7, B10, and B11 matches the condition in cell E3. The corresponding cells in column C are C5, C7, C10, and C11. Only cells C7 and C10 are empty. The formula in cell C3 returns 2 representing the total number of empty cells in cell range C3:C11 based on the condition in E3.
Explaining formula
The Evaluate Formula tool is located on the Formulas tab in the Ribbon. It is a useful feature that allows you to step through and evaluate complex formulas to understand how the calculation is being performed and identify any errors or issues. The following steps shows these detailed evaluations for the formula above.
Step 1 - Check values against a condition
The equal sign lets you compare value to value, you can also compare value to multiple values, and the result is an array.
The equal sign is a logical operator and the result is a boolean value TRUE or FALSE.
B3:B11=E3
becomes
{"Pen"; "Pencil"; "Clip"; "Pen"; "Clip"; "Pencil"; "Pen"; "Clip"; "Clip"}="Clip"
and returns
{FALSE; FALSE; TRUE; FALSE; TRUE; FALSE; FALSE; TRUE; TRUE}.
Step 2 - Filter values based on a condition
The FILTER function extracts values/rows based on a condition or criteria.
Function syntax: FILTER(array, include, [if_empty])
FILTER(C3:C11,B3:B11=E3)
becomes
FILTER(C3:C11,{FALSE; FALSE; TRUE; FALSE; TRUE; FALSE; FALSE; TRUE; TRUE})
becomes
FILTER({"";7;45;31;"";37;98;"";6}, {FALSE; FALSE; TRUE; FALSE; TRUE; FALSE; FALSE; TRUE; TRUE})
and returns
{45; ""; ""; 6}.
Step 3 - Find blank values
The equal sign lets you compare value to value, the "" double quotes mean that the equal sign compares to nothing.
FILTER(C3:C11,B3:B11=E3)=""
becomes
{45; ""; ""; 6}=""
and returns
{FALSE; TRUE; TRUE; FALSE}.
Step 5 - Add boolean values
The SUM function allows you to add numerical values, the function returns the sum in the cell it is entered in. The SUM function is cleverly designed to ignore text and boolean values, adding only numbers.
Function syntax: SUM(number1, [number2], ...)
SUM((FILTER(C3:C11,B3:B11=E3)="")*1)
becomes
SUM({FALSE; TRUE; TRUE; FALSE})
and returns 2.
FALSE is 0 (zero) and TRUE is 1.
6. Count blanks based on multiple conditions
This example demonstrates how to count empty cells based on two conditions. Cell range B3:C11 contains a data table with these header names: "Item" and "Amounts". Cell range E3:E4 contains the conditions the formula uses to extract the corresponding cells in column C.
Item | Amounts |
Pen | |
Pencil | 7 |
Clip | 45 |
Pen | 31 |
Clip | |
Pencil | 37 |
Pen | 98 |
Clip | |
Clip | 6 |
If the cell in cell range B3:B11 matches one of the conditions then the SUM function adds those cells to the total count of empty cells.
Formula in cell G3:
For example, cells B3, B5, B6, B7, B9, B10, and B11 matches the condition in cell E3. The corresponding cells in column C are C3, C5, C6, C7, C9, C10, and C11. Only cells C3, C7, and C10 are empty. The formula in cell G3 returns 2 representing the total number of empty cells in cell range C3:C11 based on the condition in E3.
Explaining formula
The Evaluate Formula tool is located on the Formulas tab in the Ribbon. It is a useful feature that allows you to step through and evaluate complex formulas to understand how the calculation is being performed and identify any errors or issues. The following steps shows these detailed evaluations for the formula above.
Step 1 - Count cells matching the conditions
The COUNTIF function calculates the number of cells that is equal to a condition.
Function syntax: COUNTIF(range, criteria)
COUNTIF(E3:E4,B3:B11)
returns {1;0;1;1;1;0;1;1;1}
Step 2 - Filter values based on array
The FILTER function extracts values/rows based on a condition or criteria.
Function syntax: FILTER(array, include, [if_empty])
FILTER(C3:C11,COUNTIF(E3:E4,B3:B11))
becomes
FILTER(C3:C11,{1;0;1;1;1;0;1;1;1})
and returns {0;45;31;0;98;0;6}
Step 3 - Check if values are empty
The equal sign lets you compare value to value, the "" double quotes mean that the equal sign compares to nothing.
FILTER(C3:C11,COUNTIF(E3:E4,B3:B11))=""
becomes
{0;45;31;0;98;0;6}=""
and returns {TRUE;FALSE;FALSE;TRUE;FALSE;TRUE;FALSE}
Step 4 - Multiply by 1
The asterisk lets you multiply values in a formula.
(FILTER(C3:C11,COUNTIF(E3:E4,B3:B11))="")*1
becomes
{TRUE;FALSE;FALSE;TRUE;FALSE;TRUE;FALSE}*1
and returns {1;0;0;1;0;1;0}
Step 5 - Add the numbers and return total of empty cells
The SUM function allows you to add numerical values, the function returns the sum in the cell it is entered in. The SUM function is cleverly designed to ignore text and boolean values, adding only numbers.
Function syntax: SUM(number1, [number2], ...)
SUM((FILTER(C3:C11,COUNTIF(E3:E4,B3:B11))="")*1)
becomes
SUM({1;0;0;1;0;1;0})
and returns 3 in cell G3.
7. Count blanks in a delimited text string
The COUNTBLANK function does not work with the TEXTSPLIT function we need a workaround to count blank empty values in an array.
The image above shows the following value in cell C3: A;;44;0; ;TRUE;#DIV/0!;Text The formula in cell C3 splits the string into an array of values based on the specified delimiting character. In this case ; (semicolon).
Formula in cell C3:
The equal sign ="" and the double quotes check if the value in the array is empty. The asterisk converts the boolean values to numerical equivalents and the sum function calculates the total number of empty array containers.
Explaining formula
The Evaluate Formula tool is located on the Formulas tab in the Ribbon. It is a useful feature that allows you to step through and evaluate complex formulas to understand how the calculation is being performed and identify any errors or issues. The following steps shows these detailed evaluations for the formula above.
Step 1 - Split strintg into an array of values
The TEXTSPLIT function splits a string into an array based on delimiting values.
Function syntax: TEXTSPLIT(Input_Text, col_delimiter, [row_delimiter], [Ignore_Empty])
TEXTSPLIT(C3,";")
returns {"A","","44","0"," ","TRUE","#DIV/0!","Text"}
Step 2 - Check if array value is empty
The equal sign lets you compare value to value, the "" double quotes mean that the equal sign compares to nothing.
TEXTSPLIT(C3,";")=""
becomes
{"A","","44","0"," ","TRUE","#DIV/0!","Text"}=""
and returns
{FALSE,TRUE,FALSE,FALSE,FALSE,FALSE,FALSE,FALSE}
Step 3 - Multiply boolean values by 1 to convert to numerical values
The asterisk lets you multiply values in a formula.
(TEXTSPLIT(C3,";")="")*1
becomes
{FALSE,TRUE,FALSE,FALSE,FALSE,FALSE,FALSE,FALSE}*1
and returns
{0,1,0,0,0,0,0,0}
Step 4 - Add numbers and return a total
The SUM function allows you to add numerical values, the function returns the sum in the cell it is entered in. The SUM function is cleverly designed to ignore text and boolean values, adding only numbers.
Function syntax: SUM(number1, [number2], ...)
SUM((TEXTSPLIT(C3,";")="")*1)
becomes
SUM({0,1,0,0,0,0,0,0}) and returns 1.
8. Count blanks in multiple cell ranges
This example demonstrates how to count empty cells across different cell ranges and worksheets. The following cell ranges contains data and some blanks: B3:B9, D3:D9, and F3:F9. You can see them clearly in the image above.
Formula in cell B12:
The formula in cell B11 counts empty cell in all specified cell ranges, they don't have to be on the same worksheet as this example demonstrates.
Explaining formula
The Evaluate Formula tool is located on the Formulas tab in the Ribbon. It is a useful feature that allows you to step through and evaluate complex formulas to understand how the calculation is being performed and identify any errors or issues. The following steps shows these detailed evaluations for the formula above.
Step 1 - Join cell ranges
The VSTACK function combines cell ranges or arrays. Joins data to the first blank cell at the bottom of a cell range or array (vertical stacking)
Function syntax: VSTACK(array1,[array2],...)
VSTACK(B3:B9,D3:D9,F3:F9)
Step 2 - Check if empty
The equal sign lets you compare value to value, the "" double quotes mean that the equal sign compares to nothing.
VSTACK(B3:B9,D3:D9,F3:F9)=""
Step 3 - Convert boolean values to numbers
The asterisk lets you multiply values in a formula.
(VSTACK(B3:B9,D3:D9,F3:F9)="")*1
returns
{0;1;0;0;0;0;0;0;0;0;1;1;0;0;1;0;0;0;0;0;1}
Step 4 - Calculate a total
The SUM function allows you to add numerical values, the function returns the sum in the cell it is entered in. The SUM function is cleverly designed to ignore text and boolean values, adding only numbers.
Function syntax: SUM(number1, [number2], ...)
SUM((VSTACK(B3:B9,D3:D9,F3:F9)="")*1)
becomes
SUM({0;1;0;0;0;0;0;0;0;0;1;1;0;0;1;0;0;0;0;0;1})
and returns 5 in cell B11.
9. Count blank cells ignoring space characters
The following formula counts blank cells even if the cell contains one or more space characters. This example demonstrates how to use the TRIM function to count empty cells in a specific cell range.
The image above shows data in cell range B3:B14, it contains all kinds of data. Text values, numbers, error values, cells containing space characters and empty cells.
Array formula in cell D5:
Excel 365 subscribers may skip the following steps to create an array formula.
How to enter an array formula
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
The Evaluate Formula tool is located on the Formulas tab in the Ribbon. It is a useful feature that allows you to step through and evaluate complex formulas to understand how the calculation is being performed and identify any errors or issues. The following steps shows these detailed evaluations for the formula above.
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.
10. Function not working
The COUNTBLANK function returns
- #NAME? error if you misspell the function name.
- does not propagate errors, meaning that if the input contains an error (e.g., #VALUE!, #REF!), the function will return the same error.
10.1 Troubleshooting the error value
When you encounter an error value in a cell a warning symbol appears, displayed in the image above. Press with mouse on it to see a pop-up menu that lets you get more information about the error.
- The first line describes the error if you press with left mouse button on it.
- The second line opens a pane that explains the error in greater detail.
- The third line takes you to the "Evaluate Formula" tool, a dialog box appears allowing you to examine the formula in greater detail.
- This line lets you ignore the error value meaning the warning icon disappears, however, the error is still in the cell.
- The fifth line lets you edit the formula in the Formula bar.
- The sixth line opens the Excel settings so you can adjust the Error Checking Options.
Here are a few of the most common Excel errors you may encounter.
#NULL error - This error occurs most often if you by mistake use a space character in a formula where it shouldn't be. Excel interprets a space character as an intersection operator. If the ranges don't intersect an #NULL error is returned. The #NULL! error occurs when a formula attempts to calculate the intersection of two ranges that do not actually intersect. This can happen when the wrong range operator is used in the formula, or when the intersection operator (represented by a space character) is used between two ranges that do not overlap. To fix this error double check that the ranges referenced in the formula that use the intersection operator actually have cells in common.
#SPILL error - The #SPILL! error occurs only in version Excel 365 and is caused by a dynamic array being to large, meaning there are cells below and/or to the right that are not empty. This prevents the dynamic array formula expanding into new empty cells.
#DIV/0 error - This error happens if you try to divide a number by 0 (zero) or a value that equates to zero which is not possible mathematically.
#VALUE error - The #VALUE error occurs when a formula has a value that is of the wrong data type. Such as text where a number is expected or when dates are evaluated as text.
#REF error - The #REF error happens when a cell reference is invalid. This can happen if a cell is deleted that is referenced by a formula.
#NAME error - The #NAME error happens if you misspelled a function or a named range.
#NUM error - The #NUM error shows up when you try to use invalid numeric values in formulas, like square root of a negative number.
#N/A error - The #N/A error happens when a value is not available for a formula or found in a given cell range, for example in the VLOOKUP or MATCH functions.
#GETTING_DATA error - The #GETTING_DATA error shows while external sources are loading, this can indicate a delay in fetching the data or that the external source is unavailable right now.
10.2 The formula returns an unexpected value
To understand why a formula returns an unexpected value we need to examine the calculations steps in detail. Luckily, Excel has a tool that is really handy in these situations. Here is how to troubleshoot a formula:
- Select the cell containing the formula you want to examine in detail.
- Go to tab “Formulas” on the ribbon.
- Press with left mouse button on "Evaluate Formula" button. A dialog box appears.
The formula appears in a white field inside the dialog box. Underlined expressions are calculations being processed in the next step. The italicized expression is the most recent result. The buttons at the bottom of the dialog box allows you to evaluate the formula in smaller calculations which you control. - Press with left mouse button on the "Evaluate" button located at the bottom of the dialog box to process the underlined expression.
- Repeat pressing the "Evaluate" button until you have seen all calculations step by step. This allows you to examine the formula in greater detail and hopefully find the culprit.
- Press "Close" button to dismiss the dialog box.
There is also another way to debug formulas using the function key F9. F9 is especially useful if you have a feeling that a specific part of the formula is the issue, this makes it faster than the "Evaluate Formula" tool since you don't need to go through all calculations to find the issue..
- Enter Edit mode: Double-press with left mouse button on the cell or press F2 to enter Edit mode for the formula.
- Select part of the formula: Highlight the specific part of the formula you want to evaluate. You can select and evaluate any part of the formula that could work as a standalone formula.
- Press F9: This will calculate and display the result of just that selected portion.
- Evaluate step-by-step: You can select and evaluate different parts of the formula to see intermediate results.
- Check for errors: This allows you to pinpoint which part of a complex formula may be causing an error.
The image above shows cell reference C3:C10 converted to hard-coded value using the F9 key.
Tips!
- View actual values: Selecting a cell reference and pressing F9 will show the actual values in those cells.
- Exit safely: Press Esc to exit Edit mode without changing the formula. Don't press Enter, as that would replace the formula part with the calculated value.
- Full recalculation: Pressing F9 outside of Edit mode will recalculate all formulas in the workbook.
Remember to be careful not to accidentally overwrite parts of your formula when using F9. Always exit with Esc rather than Enter to preserve the original formula. However, if you make a mistake overwriting the formula it is not the end of the world. You can “undo” the action by pressing keyboard shortcut keys CTRL + z or pressing the “Undo” button
10.3 Other errors
Floating-point arithmetic may give inaccurate results in Excel - Article
Floating-point errors are usually very small, often beyond the 15th decimal place, and in most cases don't affect calculations significantly.
'COUNTBLANK' function examples
The following article has a formula that contains the COUNTBLANK function.
Functions in 'Statistical' category
The COUNTBLANK function function is one of 73 functions in the 'Statistical' category.
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.
Contact Oscar
You can contact me through this contact form