• Login
  • Courses
  • Books
  • Cheat Sheets
  • Tutorials Archive
  • VBA Code Generator
  • Contact

Power Spreadsheets

Excel and VBA tutorials and training. Learn how to use Microsoft Excel and Visual Basic for Applications now.

Excel VBA Clear Cell: Step-by-Step Guide and 5 Examples to Clear Cells with Macros

Excel VBA Tutorial about how to clear cell with macrosIn this VBA Tutorial, you learn how to clear cells (including clearing cells totally, their format but not their contents, their contents but not their format, and other similar combinations) with macros.

This VBA Tutorial is accompanied by Excel workbooks containing the macros I use in the examples below. You can get immediate access to these example workbooks by subscribing to the Power Spreadsheets Newsletter.

Use the following Table of Contents to navigate to the section you're interested in.

Table of Contents

  • Related VBA and Macro Tutorials
  • #1: Clear Cell
    • VBA Code to Clear Cell
    • Process Followed by VBA to Clear Cell
    • VBA Statement Explanation
    • Macro Example to Clear Cell
    • Effects of Executing Macro Example to Clear Cell
  • #2: Clear Cell Contents and Keep Formatting
    • VBA Code to Clear Cell Contents and Keep Formatting
    • Process Followed by VBA to Clear Cell Contents and Keep Formatting
    • VBA Statement Explanation
    • Macro Example to Clear Cell Contents and Keep Formatting
    • Effects of Executing Macro Example to Clear Cell Contents and Keep Formatting
  • #3: Clear Cell Formatting
    • VBA Code to Clear Cell Formatting
    • Process Followed by VBA to Clear Cell Formatting
    • VBA Statement Explanation
    • Macro Example to Clear Cell Formatting
    • Effects of Executing Macro Example to Clear Cell Formatting
  • #4: Clear Cell Color
    • VBA Code to Clear Cell Color
    • Process Followed by VBA to Clear Cell Color
    • VBA Statement Explanation
    • Macro Example to Clear Cell Color
    • Effects of Executing Macro Example to Clear Cell Color
  • #5: Clear Cells with Zero
    • VBA Code to Clear Cells with Zero
    • Process Followed by VBA to Clear Cells with Zero
    • VBA Statement Explanation
    • Macro Example to Clear Cells with Zero
    • Effects of Executing Macro Example to Clear Cells with Zero
  • References to VBA Constructs Used in this VBA Tutorial

Related VBA and Macro Tutorials

The following VBA and Macro Tutorials may help you better understand and implement the contents below:

  • General VBA constructs and structures:

    • Learn about important VBA constructs here.

    • Learn how to work with the Visual Basic Editor here.

    • Learn how to work with Excel Sub procedures here.

    • Learn about the Excel Object Model, and how to create object references, here.

    • Learn about the Range object, and how to refer to cells, here.

    • Learn how to work with properties here.

    • Learn how to work with methods here.

    • Learn how to declare and work with variables here.

    • Learn about data types here.

    • Learn how to work with loops here.

  • Practical VBA applications and macro examples:

    • Learn how to work with worksheets using VBA here.

    • Learn how to check if a cell is empty here.

    • Learn how to delete rows here.

    • Learn how to delete blank or empty rows here.

You can find additional VBA and Macro Tutorials in the Archives.

#1: Clear Cell

VBA Code to Clear Cell

To clear cells using VBA, use a statement with the following structure:

Cells.Clear

Process Followed by VBA to Clear Cell

Identify cells to clear > clear cells entirely

VBA Statement Explanation

  1. Item: Cells.

    • VBA Construct: Range object.

    • Description: Range object representing the cells you want to clear.

      You can usually return a Range object with constructs such as the Worksheet.Range, Worksheet.Cells (with Range.Item), Range.Offset, Range.Resize or Application.ActiveCell properties. If you explicitly declare an object variable to represent Cells, use the Range object data type.

  2. Item: Clear.

    • VBA Construct: Range.Clear method.

    • Description: The Range.Clear method clears the Range object you specify (Cells). Range.Clear clears the entire Range object, including values, formulas and formatting.

Macro Example to Clear Cell

The following macro example clears cells A5 to C9 (myRange) in the worksheet named “Clear Cell” of the workbook containing the macro (ThisWorkbook).

Sub clearCell()

    'Source: https://powerspreadsheets.com/
    'For further information: https://powerspreadsheets.com/excel-vba-clear-cell/

    'declare object variable to hold reference to cells to clear
    Dim myRange As Range

    'identify cells to clear
    Set myRange = ThisWorkbook.Worksheets("Clear Cell").Range("A5:C9")

    'clear cells (including formatting)
    myRange.Clear

End Sub

Effects of Executing Macro Example to Clear Cell

The following images illustrate the results of executing the macro example.

  • Before macro execution: Cells A5 to C9 contain the string “data”, have a light blue fill, and the font is formatted as bold.

    Cells with data, fill color and bold formatting

  • After macro execution: Cells A5 to C9 (including both data and formatting) are cleared.

    Cells with cleared data and formatting

#2: Clear Cell Contents and Keep Formatting

VBA Code to Clear Cell Contents and Keep Formatting

To clear cell contents (but not formatting) using VBA, use a statement with the following structure:

Cells.ClearContents

Process Followed by VBA to Clear Cell Contents and Keep Formatting

Identify cells to clear > clear cell contents but keep formatting

VBA Statement Explanation

  1. Item: Cells.

    • VBA Construct: Range object.

    • Description: Range object representing the cells where you want to clear the contents but not the formatting.

      You can usually return a Range object with constructs such as the Worksheet.Range, Worksheet.Cells (with Range.Item), Range.Offset, Range.Resize or Application.ActiveCell properties. If you explicitly declare an object variable to represent Cells, use the Range object data type.

  2. Item: ClearContents.

    • VBA Construct: Range.ClearContents method.

    • Description: The Range.ClearContents method clears values and formulas from the Range object you specify (Cells). Range.ClearContents leaves formatting intact.

Macro Example to Clear Cell Contents and Keep Formatting

The following macro example clears the contents (but not the formatting) of cells A10 to C14 (myRange) in the worksheet named “Clear Cell” of the workbook containing the macro (ThisWorkbook).

Sub clearCellContentsKeepFormatting()

    'Source: https://powerspreadsheets.com/
    'For further information: https://powerspreadsheets.com/excel-vba-clear-cell/

    'declare object variable to hold reference to cells to clear contents but not formatting
    Dim myRange As Range

    'identify cells to clear contents and keep formatting
    Set myRange = ThisWorkbook.Worksheets("Clear Cell").Range("A10:C14")

    'clear cell contents (but not formatting)
    myRange.ClearContents

End Sub

Effects of Executing Macro Example to Clear Cell Contents and Keep Formatting

The following images illustrate the results of executing the macro example.

  • Before macro execution: Cells A10 to C14 contain the string “data”, have a light gold fill, and the font is formatted as bold.

    Cells with data, interior fill and bold formatting

  • After macro execution: Cell contents of cells A10 to C14 are cleared. The formatting is kept.

    Cells with interior fill and bold formatting

#3: Clear Cell Formatting

VBA Code to Clear Cell Formatting

To clear cell formatting using VBA, use a statement with the following structure:

Cells.ClearFormats

Process Followed by VBA to Clear Cell Formatting

Identify cells to clear > clear cell formatting

VBA Statement Explanation

  1. Item: Cells.

    • VBA Construct: Range object.

    • Description: Range object representing the cells where you want to clear cell formatting.

      You can usually return a Range object with constructs such as the Worksheet.Range, Worksheet.Cells (with Range.Item), Range.Offset, Range.Resize or Application.ActiveCell properties. If you explicitly declare an object variable to represent Cells, use the Range object data type.

  2. Item: ClearFormats.

    • VBA Construct: Range.ClearFormats method.

    • Description: The Range.ClearFormats method clears the formatting of the Range object you specify (Cells). Range.ClearFormats doesn't clear values or formulas.

Macro Example to Clear Cell Formatting

The following macro clears the cell formatting of cells A15 to C19 (myRange) of the worksheet named “Clear Cell” in the workbook containing the macro (ThisWorkbook).

Sub clearCellFormatting()

    'Source: https://powerspreadsheets.com/
    'For further information: https://powerspreadsheets.com/excel-vba-clear-cell/

    'declare object variable to hold reference to cells to clear formatting
    Dim myRange As Range

    'identify cells to clear formatting
    Set myRange = ThisWorkbook.Worksheets("Clear Cell").Range("A15:C19")

    'clear cell formatting
    myRange.ClearFormats

End Sub

Effects of Executing Macro Example to Clear Cell Formatting

The following images illustrate the results of executing the macro example.

  • Before macro execution: Cells A15 to C19 contain the string “data”, have a light green fill, and the font is formatted as bold.

    Cells with data, interior fill and bold formatting

  • After macro execution: The formatting of cells A15 to C19 is cleared.

    Cells with data but cleared formatting

#4: Clear Cell Color

VBA Code to Clear Cell Color

To clear cell color using VBA, use a statement with the following structure:

Cells.Interior.Color = xlColorIndexNone

Process Followed by VBA to Clear Cell Color

Identify cells to clear > set interior color of cells to no color

VBA Statement Explanation

  1. Item: Cells.

    • VBA Construct: Range object.

    • Description: Range object representing the cells where you want to clear cell formatting.

      You can usually return a Range object with constructs such as the Worksheet.Range, Worksheet.Cells (with Range.Item), Range.Offset, Range.Resize or Application.ActiveCell properties. If you explicitly declare an object variable to represent Cells, use the Range object data type.

  2. Item: Interior.

    • VBA Construct: Range.Interior property and Interior object.

    • Description: The Range. Interior property returns an Interior object representing the interior of the cell range you specify (Cells).

  3. Item: Color.

    • VBA Construct: Interior.Color property.

    • Description: The Interior.Color property allows you to set the primary color of the cell interior represented by the Interior object returned by Range.Interior.

  4. Item: =.

    • VBA Construct: Assignment operator.

    • Description: The assignment operator assigns the xlColorIndexNone value to the Interior.Color property.

  5. Item: xlColorIndexNone.

    • VBA Construct: xlColorIndexNone constant.

    • Description: The xlColorIndexNone constant specifies that the color of the Interior object representing the interior of Cells is none.

Macro Example to Clear Cell Color

The following macro clears the cell color of cells A20 to C24 (myRange) in the worksheet named “Clear Cell” of the workbook containing the macro (ThisWorkbook).

Sub clearCellColor()

    'Source: https://powerspreadsheets.com/
    'For further information: https://powerspreadsheets.com/excel-vba-clear-cell/

    'declare object variable to hold reference to cells to clear cell color
    Dim myRange As Range

    'identify cells to clear cell color
    Set myRange = ThisWorkbook.Worksheets("Clear Cell").Range("A20:C24")

    'clear cell color
    myRange.Interior.Color = xlColorIndexNone

End Sub

Effects of Executing Macro Example to Clear Cell Color

The following images illustrate the results of executing the macro example.

  • Before macro execution: Cells A20 to C24 contain the string “data”, have a light orange fill, and the font is formatted as bold.

    Cells with data, interior fill and bold formatting


  • After macro execution: The fill color of cells A20 to C24 is cleared.

    Cells with data and bold formatting, but no cell fill color

#5: Clear Cells with Zero

VBA Code to Clear Cells with Zero

To clear cells with zero within a cell range using VBA, use a macro with the following statement structure:

For Each Cell In Range
    If Cell.Value = myValue Then Cell.Clear
Next Cell

Process Followed by VBA to Clear Cells with Zero

Identify cell range > loop through cells > identify cells with zero > clear cell

VBA Statement Explanation

Lines #1 and #3: For Each Cell In Range | Next Cell

  1. Item: For Each… In… Next.

    • VBA Construct: For Each… Next statement.

    • Description: The For Each… Next statement repeats the statement within the loop (line #2) for each element (Cell) in the cell range (Range) you want to search for zeroes in.

  2. Item: Cell.

    • VBA Construct: Element of the For Each… Next statement and object variable of the Range object data type.

    • Description: The Element of the For Each… Next statement is an object variable used to iterate through the elements (Cell) of the cell range (Range) you want to search for zeroes in.

      If you explicitly declare an object variable to represent Cell, use the Range object data type.

  3. Item: Range.

    • VBA Construct: Group of the For Each… Next statement and Range object.

    • Description: The For Each… Next statement repeats the statements within the loop (line #2) for each element (Cell) in the Group (Range). Range is a Range object representing the cells where you want to search for zeroes.

      You can usually return a Range object with constructs such as the Worksheet.Range, Worksheet.Cells (with Range.Item), Range.Offset, Range.Resize or Application.ActiveCell properties. If you explicitly declare an object variable to represent Range, use the Range object data type.

Line #2: If Cell.Value = myValue Then Cell.Clear

  1. Item: If… Then.

    • VBA Construct: If… Then… Else statement.

    • Description: The If… Then… Else statement conditionally executes a group of statements depending on the value of an expression. For these purposes:

      • The If… Then… Else statement tests the specified condition (Cell.Value = myValue).

      • If the condition is met and returns True: Cell.Clear is executed.

      • If the condition is not met and returns False: Execution continues with the statement following the If… Then… Else statement (Next Cell).

  2. Item: Cell.

    • VBA Construct: Object variable of the Range object data type.

    • Description: Cell is an object variable used to iterate through the elements of the cell range (Range) you want to search for zeroes in. Within the If… Then… Else statement, Cell represents the individual cell the For Each… Next loop is currently iterating through.

      If you explicitly declare an object variable to represent Cell, use the Range object data type.

  3. Item: Value.

    • VBA Construct: Range.Value property.

    • Description: The Range.Value property returns the value in the cell the For Each…Next loop is currently iterating through.

  4. Item: myValue.

    • VBA Construct: Variable of a numeric data type.

    • Description: myValue represents the value you want to search for and use to determine which cells to clear. Within the macro structure used in this VBA Tutorial, myValue is 0 (zero).

      If you explicitly declare a variable to represent myValue, use a numeric data type such as Long, Single or Double (depending on the value you're searching for).
  5. Item: Cell.Value = myValue.

    • VBA Construct: Condition of If… Then… Else statement.

    • Description: This condition is an expression that evaluates to True or False. Cell.Value = myValue returns True or False, as follows:

      • True: Value of Cell is equal to myValue (zero).

      • False: Value of Cell isn't equal to myValue (zero).

  6. Item: Clear.

    • VBA Construct: Range.Clear method.

    • Description: The Range.Clear method clears the cell the For Each… Next loop is currently iterating through. Range.Clear clears the entire Range object, including values, formulas and formatting.

      If you don't want to clear the entire Range object, but only its contents, formatting or cell color, please refer to the appropriate sections above.

Macro Example to Clear Cells with Zero

The following macro example clears the cells with zero (0) in cells A25 to C29 (myRange) in the worksheet named “Clear Cell” of the workbook containing the macro (ThisWorkbook).

Sub clearCellsWithZero()

    'Source: https://powerspreadsheets.com/
    'For further information: https://powerspreadsheets.com/excel-vba-clear-cell/

    'declare object variables to hold references to cell range where you search for zeroes
    Dim myRange As Range

    'declare object variable used to iterate through the elements of the cell range
    Dim iCell As Range

    'declare variable to hold value (zero) you search for
    Dim myValue As Long

    'identify cells to search for zeroes
    Set myRange = ThisWorkbook.Worksheets("Clear Cell").Range("A25:C29")

    'set value (zero) to search for
    myValue = 0

    'loop through each cell (iCell) of the cell range (myRange)
    For Each iCell In myRange

        'test if value is zero. If condition is met, clear cell
        If iCell.Value = myValue Then iCell.Clear

    Next iCell

End Sub

Effects of Executing Macro Example to Clear Cells with Zero

The following images illustrate the results of executing the macro example.

  • Before macro execution: Cells A25 to C29 contain the string “data” or the value zero (0), have a light gray fill, and the font is formatted as bold.

    Cells with data and zero, fill color and bold formatting


  • After macro execution: Cells between A25 to C29 containing a zero (0) are cleared (including both data and formatting).

    Some cells with data, fill color and bold formatting

References to VBA Constructs Used in this VBA Tutorial

Use the following links to visit the appropriate webpage in the Microsoft Developer Network:

  1. Identify the workbook and worksheet where the cells to clear are located:

    • Workbook object.

    • Application.ActiveWorkbook property.

    • Application.ThisWorkbook property.

    • Application.Workbooks property.

    • Worksheet object.

    • Application.ActiveSheet property.

    • Workbook.Worksheets property.

  2. Identify the cells to clear:

    • Range object.

    • Worksheet.Range property.

    • Worksheet.Cells property.

    • Application.ActiveCell property.

    • Application.Selection property.

    • Range.Range property.

    • Range.Cells property.

    • Range.Item property.

    • Range.Offset property.

    • Range.Resize property.

    • For Each… Next statement.

    • If… Then… Else statement.

    • Range.Value property.

  3. Clear cells:

    • Range.Clear method.

    • Range.ClearContents method.

    • Range.ClearFormats method.

    • Interior object.

    • Range.Interior property.

    • Interior.Color property.

    • xlColorIndex enumeration.

  4. Work with variables and data types:

    • Dim statement.

    • Set statement.

    • = operator.

    • Data types:

      • Double data type.

      • Long data type.

      • Single data type.

I publish a lot of Tutorials and Training Resources about Microsoft Excel and VBA. Here are some of my most popular Excel Training Resources:

  1. Free Excel VBA Email Course
  2. Excel Macro Tutorial for Beginners
  3. Excel Power Query (Get and Transform) Tutorial for Beginners
  4. Excel Keyboard Shortcut Cheat Sheet
  5. Excel Resources
Terms and Conditions

Privacy Policy

Limit of Liability and Disclaimer of Warranty

Affiliate Disclosure

Copyright © 2015–2023 PDS Intelligence Pte. Ltd. All rights reserved.
Excel ® is a registered trademark of the Microsoft Corporation. Power Spreadsheets is not affiliated with the Microsoft Corporation.