Counting Empty Colored Cells

by Allen Wyatt
(last updated February 12, 2016)

2

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.)

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

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

Keeping Callouts Positioned

Using graphics to add callouts to your graphics is a common occurrence in Word. Here's how to stop all those graphics from ...

Discover More

AutoFilling from a Custom List

AutoFill can be a real timesaver if you often work with set lists of data. You can define your own custom lists and then use ...

Discover More

Appending to a Non-Excel Text File

Does your macro need to add information to the end of a text file? This is called appending, and is done using the technique ...

Discover More

Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!

More ExcelTips (ribbon)

Determining the Current Directory

When you use a macro to do file operations, it works (by default) within the current directory. If you want to know which ...

Discover More

Friendly and Informative Error Handling

When creating macros, it is helpful to know what is going on within the macro itself in case an error crops up. Here's one ...

Discover More

Limiting Scroll Area

If you need to limit the cells that are accessible by the user of a worksheet, VBA can come to the rescue. This doesn't ...

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}] in your comment text. You’ll be prompted to upload your image when you submit the comment. 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 6 + 4?

2015-03-01 23:23:28

peregrinus

What about counting non blank colored cells? How would one go about that?


2013-04-12 07:16:13

Andre

Hi, I am not educated in VB, but I can copy and paste. This macro seems to be thing I need. I have a spreadsheet with dates, when after a certain period it formats red, orange,grey and some stay clear. I need to count the amount of dates in the clear cells. I cannot count blanks as some the other coloured cells can be without a date.
After I have entered this macro... what formula should I use in the sheet.
Your help will be greatly appreciated.
Cheers


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.