Removing Cells Containing Specific Terms

Written by Allen Wyatt (last updated July 3, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365


2

Ankur has a worksheet that has thousands of cells containing various terms. He needs to delete a large number of those terms and the cells in which they occur. For instance, he may need to delete all the cells containing terms like "google," "youtube," "linkedin," and numerous other terms. Ankur knows he can do a search and replace for each of these terms, but that is quite tedious. He wonders if there is a way he can identify all the terms to be removed and then have Excel remove them from those thousands of cells.

If you need to do this type of thing on a regular basis, then the best solution is to use a macro. The trick is how you specify, in the macro, exactly what you want to replace. One way is to stuff the information into an array, as in the following example:

Sub RemoveTerms1()
    Dim vTerm As Variant
    Dim vArray As Variant

    vArray = Array("google", "youtube", "linkedin")
    For Each vTerm in vArray
        Selection.Replace What:=vTerm, _
          Replacement:="", LookAt:=xlPart
    Next vTerm
End Sub

The terms being looked for are placed in the vArray array, and then each member of the array (each term) is stepped through. The Replace method is used with the Selection object to do the actual replacements. The macro doesn't remove cells; it simply removes any text that matches the term. When replacing, the searching is case insensitive, so that "google" matches "Google."

Since the Selection object is used, it is important to make sure you select the list you want to process before actually running the macro. If you don't, then nothing is replaced.

If you prefer, you could create a macro that pulled the terms from a range of cells in the workbook.

Sub RemoveTerms2()
    Dim c As Range
    Dim rngSource As Range
    Dim vTerm As Variant
    Dim arrTerms As Variant
    Dim i As Integer

    i = -1
    arrTerms = Array()
    For Each c In Range("D1:D9").Cells
        If Trim(c.Value) > "" Then
            i = i + 1
            ReDim Preserve arrTerms(i)
            arrTerms(i) = Trim(c.Value)
        End If
    Next c

    On Error Resume Next
    Set rngSource = Application.InputBox( _
                    Prompt:="Please select Range", _
                    Title:="Removing Cells Containing Terms", _
                    Default:=ActiveSheet.UsedRange.Address, Type:=8)
    On Error GoTo 0
    If rngSource Is Nothing Then
        MsgBox ("You didn't specify a range to process")
    Else
        For Each vTerm in arrTerms
            rngSource.Replace What:=vTerm, _
              Replacement:="", LookAt:=xlWhole
        Next vTerm
    End If
End Sub

This macro pulls the search terms from the range D1:D9 and then prompts you to choose the range of cells you want to process. It uses the same Replace method that was used in the previous macro, except it specifies the LookAt parameter to be xlWhole. This means that the search term needs to match the entire cell in order to be removed. The terms are still considered case insensitive, though.

Note that the examples so far don't actually delete any cells; they simply delete contents of cells. In many cases this is exactly what you want because you don't want to disrupt the layout of the actual worksheet. If you really do want to delete cells, then you wouldn't use the Replace method. Instead, you could turn on expanded text comparison and use the Like operator to see if there is a match.

Option Compare Text

Sub RemoveTerms3()
    Dim c As Range
    Dim rngSource As Range
    Dim vTerm As Variant
    Dim arrTerms As Variant
    Dim i As Integer
    Dim sLook As String

    i = -1
    arrTerms = Array()
    For Each c In Range("D1:D9").Cells
        If Trim(c.Value) > "" Then
            i = i + 1
            ReDim Preserve arrTerms(i)
            arrTerms(i) = Trim(c.Value)
        End If
    Next c

    On Error Resume Next
    Set rngSource = Application.InputBox( _
                    Prompt:="Please select Range", _
                    Title:="Removing Cells Containing Terms", _
                    Default:=ActiveSheet.UsedRange.Address, Type:=8)
    On Error GoTo 0
    If rngSource Is Nothing Then
        MsgBox ("You didn't specify a range to process")
    Else
        For Each vTerm in arrTerms
            sLook = "*" & vTerm & "*"
            For Each c In rngSource
                If c.Value Like sLook Then c.Delete
            Next
        Next vTerm
    End If
End Sub

Note that the search terms are still pulled from the D1:D9 range and you are still asked for the range you want to process. From there, though, the process is different: The macro examines each cell and if there is a partial match, then the cell is deleted.

In order for this variation on the macro to work properly, you'll need to include the Option Compare Text line outside of the procedure itself. This instructs VBA to enable the keywords (such as Like) that allow comparing text.

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 (13373) 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

Understanding Styles

Styles are a key concept in Microsoft Word. If you understand styles, you will find it much easier to use Word effectively.

Discover More

Capturing a Screen

A picture is worth a thousand words, but getting the picture—particularly a screen shot—into a workbook may ...

Discover More

Copying Found Items to a New Document

Word allows you to use its searching capabilities to easily find multiple items in a document. What if you want to copy ...

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)

Searching for Wildcards

Wildcard characters can be used within the Find and Replace tool, but what if you want to actually search for those ...

Discover More

Superscripts in Find and Replace

The find and replace used in Excel is less powerful than its counterpart in Word, so it is not able to do some of the ...

Discover More

Finding and Replacing in Text Boxes

Finding and replacing information in a worksheet is easy. Finding and replacing in other objects (such as text boxes or ...

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 four minus 0?

2021-10-14 16:09:11

J. Woolley

@Sari
To clear cells containing "Printed" followed by a date and a time:

Sub RemoveTerms4()
    Dim rCell As Range
    Dim sValue() As String
    Dim bOK As Boolean
    Dim dDateTime As Date
    Const sTerm As String = "Printed"
    Set rCell = Selection.Cells(1)
    Do While True
        Set rCell = Selection.Find( _
            What:=sTerm, _
            After:=rCell, _
            LookIn:=xlValues, _
            LookAt:=xlPart, _
            MatchCase:=True)
        If rCell Is Nothing Then Exit Do
        sValue = Split(rCell.Value)
        bOK = (sValue(0) = sTerm)
        On Error Resume Next
        dDateTime = DateValue(sValue(1))
        bOK = (bOK And Err = 0)
        dDateTime = TimeValue(sValue(2))
        bOK = (bOK And Err = 0)
        On Error GoTo 0
        If bOK Then rCell.Value = ""
    Loop
End Sub

As stated in the Tip: "Since the Selection object is used, it is important to make sure you select the list you want to process before actually running the macro. If you don't, then nothing is replaced."

Unrelated to this, but for your interest see
https://sites.google.com/view/MyExcelToolbox/


2021-10-13 22:08:18

Sari

Hi Allen, this is very helpful thankyou. However, I need help on create VBA code to remove cell containing specific text followed by date and time which differ each time we download the data. Example "Printed 14/10/2021 13:05:21" where need to remove all data in the cell. We have tried to use your first code above however it only remove the word "print" and not all the data (date and time). Thank you


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.