Specialcells in VBA: 7 Critical Examples
Contents
What are Specialcells?
Specialcells are a group of cells that belong to the same data type/format/color or have the same type of content like comments or blank. They are defined and used as a range object. This feature is useful when a change has to be done in several similar cells across a sheet.
For example, you can:
- Change all numbers to currencies/dates in an Excel sheet
- Remove rows with blank cells in a specific column
- Find and replace values
- Color, underline, or format all text data in a sheet
…and much more.
Syntax:
<Expression> . SpecialCells(Type:= <Type> , Value:= <Value> )
Or
<Expression> . SpecialCells( <Type> , <Value> )
Where:
- Expression can be a defined range object. E.g.:
- Cells
- Range(“A5:E15”)
- Application.UsedRange
- Type can be any one of the below mentioned types:
- xlCellTypeAllFormatConditions (refers to all cells that are formatted)
- xlCellTypeAllValidation (refers to all cells that contain datavalidation)
- xlCellTypeBlanks (refers to all cells that are blank)
- xlCellTypeComments (refers to all cells with notes/comments inserted)
- xlCellTypeConstants (refers to all cells that contain constants (either numbers or text) )
- xlCellTypeFormulas (refers to all cells that contain some formulas)
- xlCellTypeLastCell (refers to the last cell in all used ranges)
- xlCellTypeSameFormatConditions (refers to all cells with the same formatting as well as conditional formatting)
- xlCellTypeSameValidation (refers to all cells with the same set of datavalidation rules)
- xlCellTypeVisible (refers to all cells that are visible)
A combination of more than one of the types pointed above can also be used.
<Value>
can be anything specific to the mentioned datatype (options under point 2)
E.g. constants can either be:
- xlTextValues
- xlNumbers
How to Use Specialcells with Examples
Specialcells with Numbers
Let us try to find the number of bank customers who are deposit a principal amount in the bank for exactly four years.
Here is a piece of code that will loop through the range of cells from B2 to B12 that contain numbers. There is a counter that keeps incrementing if the cell that is looped through contains the value “4.”
Sub special_cells() 'setting the variable value initially Count = 0 'looping through a range of Cells For Each cell In Range("B2:B12").SpecialCells(xlCellTypeConstants, xlNumbers) 'Printing each cell value Debug.Print cell.Value 'Incrementing count if a cell with value "4" is found If Trim(cell.Value) = 4 Then Count = Count + 1 End If Next ' Finally display the no of cells with value "4" MsgBox Count End Sub
Here is the output that shows the number of customers who deposit for four years in a message box:
The immediate window screenshot also clearly shows that cells in the range that did not contain numbers have been ignored because we had called that out using the specialcells method.
Deletion of Blank Rows
In the same example explained above, let us delete the rows with blank cells in the “No. of Years” column.
Sub remove_blankrows() ' within the mentioned range if the cell identified is blank, the the entire row of that cell is deleted. Range("B2:B12").SpecialCells(xlCellTypeBlanks).EntireRow.Delete End Sub
On running the above code on the same example, we can see that the row with a blank cell (row number 11) has been deleted.
Counting Logical Values
Logical values are still considered constants. In this example, we consider a range of cells that contain just Boolean values i.e. True and False.
Sub special_cells_demo() 'setting the variable value initially Count = 0 'looping through a range of Cells For Each cell In Range("A2:A7").SpecialCells(xlCellTypeConstants, xlLogical) 'Printing each cell value Debug.Print cell.Value 'Incrementing count if a cell with value "true" is found If Trim(cell.Value) = True Then Count = Count + 1 End If Next ' Finally display the no of cells with value "4" MsgBox Count End Sub
Output:
The Boolean/logical value “True” is repeated four times in the range that has been called out in our code. Hence the message box has finally displayed “4.”
The immediate window here shows all the values that the “For loop” has considered as part of this range.
No Cells are Found: Error
If the range that we specify for specialcells do not fall under the criteria specified under type and value, then we’ll hit an error.
For example, in the same example mentioned above, if we change the range from A12 to A17, which are blank cells, then we will encounter a runtime error as the specialcells are looking for logical values in a blank range.
In the same code snipped used for the previous example, replace the line of code that refers to the range. And ensure that the range you mention in the code does not contain any data.
For Each cell In Range("A12:A17").SpecialCells(xlCellTypeConstants, xlLogical)
To overcome this error, we can use the “On Error Resume Next” statement.
Coloring Cells That Contain Specific Text
Here is another example of some text in a table. It is about ICC Men’s Cricket World Cup Winners—50 Overs.
Let us format all the cells that have “England” as the text.
First, we loop through all the cells of the entire sheet that have text. Then inside the loop we check if the text value is “England”. If yes, we color the font blue.
Sub special_cells_constants () ' loop through all the cells containing text data For Each cell In Application.Cells.SpecialCells(xlCellTypeConstants, xlTextValues) ' If value is "England" then colour it in blue. The colour index 5 stands for blue If cell.Value = "England" Then cell.Font.ColorIndex = 5 End If Next End Sub
Formatting the Numbers
Here is an example where the marks of students are converted into percentages.
Sub spl_cells2() ' convert all cells with numbers in column B to Percentage format Range("B:B").SpecialCells(xlCellTypeConstants, xlNumbers).Style = "Percent" End Sub
Can you see that the percentage conversion is not what we expected? It is necessary to divide the numbers by 100 before/after converting them to the percentage style. So, let’s update the code.
Sub spl_cells2() ' divide all numbers in the said range by 100 in order to convert it to percentage. For Each cell In Range("B:B").SpecialCells(xlCellTypeConstants, xlNumbers) cell.Value = cell.Value / 100 Next ' convert all cells with numbers in column B to Percentage format Range("B:B").SpecialCells(xlCellTypeConstants, xlNumbers).Style = "Percent" End Sub
Output: Finally, we converted the marks properly.
Defining a Range Object and Using it Throughout the Code
It is also possible to define a range of specialcells and use the range object wherever required instead of using the lengthy code to define it every time.
Examples:
In one of the examples discussed above, we are defining the numbers in the range twice. Instead, it can be defined once and used many times.
Sub spl_cells2() ' declare a range object Dim rng As Range ' define the range object Set rng = Range("B:B").SpecialCells(xlCellTypeConstants, xlNumbers) ' divide all numbers in the said range by 100 in order to convert it to percentage. For Each cell In rng cell.Value = cell.Value / 100 Next ' convert all cells with numbers in column B to Percentage format ' change number to percentage format rng.Style = "Percent" ' set font colour to pink rng.Font.ColorIndex = 7 ' increase the size of font to 15 rng.Font.Size = 15 ' apply italics style to the font rng.Font.Italic = True ' make the text look bold rng.Font.Bold = True End Sub
Using the code above, we have formatted the numbers in the range using the “range object” easily.
Output:
We can also wrap this formatting code within the with statement to reduce the lines of code/maintain the code easily.
Conclusion:
The specialcells function in VBA is a great help and a time saver when we want to work on a huge amount of data. It can help a lot on formatting/validating cells of the same type. This feature can be widely used in reporting and clean-up of data in Excel.
The only drawback is that we will not be able to reverse the actions performed using the VBA code. Hence, we need to be cautious of what we want to achieve as the impact will be irreversible and huge (in case of a large amount of data). One suggestion to overcome this problem is to create a backup before running the developed code, even if you are a great techie, and good at building data logic.