Counting Empty Colored Cells

Written by Allen Wyatt (last updated January 26, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365


Cindy has a fully formatted worksheet that uses color in many cells. Some of the cells have values in them; many do not. She needs a way to count any colored cells that are empty and wonders if there is a quick way to do this.

There are a few ways you can get the information you need. One way is to go through these steps:

  1. Figure out which color it is that you want to use in your count.
  2. Press F5. Excel displays the Go To dialog box.
  3. Click the Special button. Excel displays the Go To Special dialog box. (See Figure 1.)
  4. Figure 1. The Go To Special dialog box.

  5. Select the Blanks radio button.
  6. Click OK. Now all the blank cells in the worksheet are selected.
  7. Press Ctrl+F. Excel displays the Find tab of the Find and Replace dialog box.
  8. Click the Options button to expand the dialog box. (See Figure 2.)
  9. Figure 2. The Find tab of the Find and Replace dialog box.

  10. Click the Format button. Excel displays the Find Format dialog box.
  11. Make sure the Fill tab is displayed. (See Figure 3.)
  12. Figure 3. The Fill tab of the Find Format dialog box.

  13. Click on the color you want to search for. (This is the color you determined in step 1.)
  14. Click OK to close the Find Format dialog box.
  15. Click Find All.

When you perform these steps, Excel shows, at the bottom of the Find and Replace dialog box, how many cells it found that match your color. Since you started the search with only blank cells selected, the resulting count is all those cells that are blank that are filled with the color.

Of course, if you need to determine this count quite a few times, then these steps can get very tedious very quickly. In such cases it is a better idea to use a macro. The following macro steps through each blank cell in whatever range you have selected and checks to see if it contains a pattern or a color and is empty. If the conditions are fulfilled, then a counter for that color is incremented.

Sub CountBlankColors1()
    Dim c As Range
    Dim J As Integer
    Dim ColorCount(56) As Long

    ActiveSheet.Range("a1").CurrentRegion.SpecialCells(xlCellTypeBlanks).Select

    For Each c In Selection
        With c.Interior
            If .Pattern <> xlNone Then
                If .ColorIndex <> xlNone Then
                    If IsEmpty(c) Then
                        ColorCount(.ColorIndex) = _
                          ColorCount(.ColorIndex) + 1
                    End If
                End If
            End If
        End With
    Next c

    sTemp = "These are the color counts" & vbCrLf & vbCrLf
    For J = 0 To 56
        If ColorCount(J) > 0 Then
            sTemp = sTemp & "Color " & J & ": " & ColorCount(J) & vbCrLf
        End If
    Next J

    MsgBox sTemp
End Sub

Of course, you might not want to count different colors individually. Instead, you might want to know simply how many blank cells are filled with any color, in aggregate. In that case the macro becomes much simpler.

Sub CountBlankColors2()
    Dim c As Range
    Dim x As Long

    x = 0
    ActiveSheet.Range("a1").CurrentRegion.SpecialCells(xlCellTypeBlanks).Select

    For Each c In Selection
        If c.Interior.Pattern <> xlNone Then
            If c.Interior.ColorIndex <> xlNone Then
                If IsEmpty(c) Then x = x + 1
            End If
        End If
    Next c
    MsgBox "Number of colored blank cells: " & x
End Sub

It should be noted that these approaches don't take into consideration if the cell is colored through the use of a conditional format or not. (In fact, they don't take conditional formats into account at all.)

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

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

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

Magnifying Only the Current Cell

You can use the Zoom feature of Excel to magnify what Excel shows of your workbook, but it affects the entire screen. ...

Discover More

Specifying a Paper Tray in a Macro

You may want to use a macro to process and then print your document. Part of that printing may involve specifying which ...

Discover More

Changes in Font Size when Copying

Have you ever copied information from one worksheet to another, only to have the information you paste not look the way ...

Discover More

Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!

More ExcelTips (ribbon)

Deleting Every X Rows

Grab some info from a source other than Excel, and you may find the need to delete a certain pattern of rows from a ...

Discover More

Calculating an ISBN Check Digit

ISBNs are used to uniquely identify books. You may need to know if an ISBN is valid or not, which involves calculating ...

Discover More

Macro, while Running, Stops Excel from Responding

When running a macro, have you ever seen Excel appear to stop responding? This can be frustrating, but there are a couple ...

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 six minus 6?

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.