Written by Allen Wyatt (last updated May 25, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
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:
Figure 1. The Go To Special dialog box.
Figure 2. The Find tab of the Find and Replace dialog box.
Figure 3. The Fill tab of the Find Format dialog box.
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:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12581) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021.
Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!
Excel allows you to add pictures to your worksheet, even within a macro. However, you might have a bit harder time ...
Discover MoreYou can manually copy macros from one workbook to another, but what if you want to automate the copying process? Here's ...
Discover MoreDo you get tired of the dialog box that says "do you want to enable macros" that is displayed when you open a workbook. ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2024-05-29 16:21:20
J. Woolley
The Tip says its macros "don't take conditional formats into account at all." My comment dated 2024-05-27 included two macros named CountEmptyColored and CountBlankColored. To account for conditional formats as well as fill formats in each of those macros, simply replace the following statement
With c.Interior
with this statement
With c.DisplayFormat.Interior
Similar changes could be made to the Tip's macros.
2024-05-28 15:30:57
J. Woolley
Re. the first two paragraphs of my most recent comment below:
"Define an empty cell as one with no content and a blank cell as one that appears empty but might have content. A blank cell might be empty or it might contain a single apostrophe (') or a space character or a formula that returns null text (""), etc.
"The Range.SpecialCells(xlCellTypeBlanks) method returns empty cells only; blank cells are not included despite the name."
When c is a Range object representing a single cell, VBA's IsEmpty(c) function returns True for an empty cell and False for a blank cell that is not empty. Therefore, the Tip's use of IsEmpty(c) in its macros is superfluous.
Excel's ISBLANK function returns TRUE for an empty cell and FALSE for a blank cell that is not empty; therefore, it should be named ISEMPTY.
Notice Excel's WorksheetFunction object does not include an IsBlank method because that would duplicate VBA's IsEmpty function.
Using the above definitions of blank and empty, My Excel Toolbox includes the following two functions:
=IsCellBlank(Target)
=IsCellEmpty(Target)
IsCellBlank returns TRUE if Target is blank, FALSE if not.
IsCellEmpty returns TRUE if Target is empty, FALSE if not.
If Target is a contiguous range with more than one cell, an array is returned with TRUE/FALSE corresponding to each cell in Target.
See https://sites.google.com/view/MyExcelToolbox/
2024-05-27 11:22:04
J. Woolley
Define an empty cell as one with no content and a blank cell as one that appears empty but might have content. A blank cell might be empty or it might contain a single apostrophe (') or a space character or a formula that returns null text (""), etc.
The Range.SpecialCells(xlCellTypeBlanks) method returns empty cells only; blank cells are not included despite the name.
Here's a version of the Tip's CountBlankColors2 that counts empty colored cells as requested by Cindy.
Sub CountEmptyColored()
Dim c As Range, x As Long
x = 0
On Error GoTo Done
ActiveSheet.UsedRange.SpecialCells(xlCellTypeBlanks).Select
On Error GoTo 0
For Each c In Selection
With c.Interior
If .Pattern = xlSolid Then
If .ColorIndex <> xlAutomatic Then x = x + 1
ElseIf .Pattern <> xlNone Then
x = x + 1
End If
End With
Next c
Done: MsgBox "Number of empty colored cells: " & x
End Sub
Here's a version that counts blank colored cells, which Cindy might prefer.
Sub CountBlankColored()
Dim c As Range, x As Long
x = 0
ActiveSheet.UsedRange.Select
For Each c In Selection
If Trim(c.Value) = "" Then
With c.Interior
If .Pattern = xlSolid Then
If .ColorIndex <> xlAutomatic Then x = x + 1
ElseIf .Pattern <> xlNone Then
x = x + 1
End If
End With
End If
Next c
MsgBox "Number of blank colored cells: " & x
End Sub
Notice UsedRange includes cells with a fill color or pattern. A cell with a pattern will have a color and vice versa. But if the pattern is solid and the color is automatic, the cell will have the normal background color and appear to have no color; such cells are not counted in these macro versions but are counted by the Tip's macros. Finally, xlPatternNone and xlColorIndexNone are the same as xlNone, xlPatternSolid is the same as xlSolid, and xlColorIndexAutomatic is the same as xlAutomatic.
2024-05-25 14:40:47
J. Woolley
Re. my previous comment below, SpecialCells(...) is a method, not a property.
2024-05-25 14:37:55
J. Woolley
The following statement should be added to the Tip's CountBlankColors1 macro
Dim sTemp As String
In both macros, the following statement
ActiveSheet.Range("a1").CurrentRegion.SpecialCells(xlCellTypeBlanks).Select
probably should be replaced by this statement
ActiveSheet.Range("a1").SpecialCells(xlCellTypeBlanks).Select
but the result might be the same.
Notice when cells in the range A1:B2 are blank (empty), the following statement
ActiveSheet.Range("a1").CurrentRegion.Select
selects only cell A1 even if cells beyond A1:B2 are not blank. The property SpecialCells(...) apparently extends this selection beyond CurrentRegion to UsedRange.
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments