Removing Cells Containing Specific Terms

by Allen Wyatt
(last updated February 7, 2015)

10

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 use 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 area still asked for the range you want to process. From there, though, the process is different: The macro examines each cell an 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.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13373) 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

Building Your Own Web Page

Want to build a Web page using Word? Here's an overview of how it works.

Discover More

Changing Your Company Name

The installation process for Office and Excel allows you to specify a company name. If your company name later changes, you ...

Discover More

Finding the Date Associated with a Negative Value

When working with data taken from the real world, you often have to determine which certain conditions were met, such as when ...

Discover More

Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!

More ExcelTips (ribbon)

Using Find and Replace to Pre-Pend Characters

Need to add some characters to the beginning of the contents in a range of cells? It's not as easy as you might hope, but ...

Discover More

Finding Boolean Values

Excel worksheets can contain all sorts of data. One thing you might store in a worksheet is a range of Boolean (TRUE or ...

Discover More

Searching a Workbook by Default

When you display the Find tab of the Find and Replace dialog box, you'll notice that any search, by default, will be on the ...

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. Maximum image size is 8Mpixels. 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 three more than 5?

2015-03-02 16:55:52

DippyDoo

Dave,

I see it's been a little while, have you tried to insert the character code into the array to be removed to determine if that works?


2015-02-11 19:21:38

Dave P

Thank you, Peter, for the suggestion. My challenge, however, is that I need to remove all 3 of those characters when (and if) they show up. SUBSTITUTE works well to get rid of one of them, but I cannot figure out how to get rid of all 3 within one formula?

Example: If you changed your B18 cell to say: John's, "Sales"

I would need to remove all 3 of the problem characters (' & , & "). Any ideas?


2015-02-10 11:02:12

Peter Atherton

Dave P

It is difficult to imagine your formulas, examples often help. However,
the solution is in the formula.
B18 = John's Sales Ci8 = 693
John's Sales:=693
Johns Sales:=693

B19 formula = =B18&":="&C18
B20 formula =
=SUBSTITUTE(B18,"'","")&":="&C18

Maybe this can help


2015-02-10 10:41:52

Peter

Add another variable to count each time a change is made:
For Each c In rngSource
If c.Value Like sLook Then
c.Delete
Counter = counter + 1
End If
Next

The before End Sub add

msgbox counter "items deleted"


2015-02-09 11:53:18

Dave P

I have to remove certain characters (commas, apostrophes, and quotes) that pull into cells due to formulas that were used. I tested the first macro in this tip and it works beautifully on cells only containing text. It did not, however, remove the problem characters from formula results. Does anyone have a solution to this?? Thanks!!


2015-02-09 05:23:22

KRoss

Thanks to all those who replied to my question, I appreciate the additional education.
Keith


2015-02-09 03:32:17

Felix Hinkel

Hi Keith,

Just saw your question. What 'Allen's code does:
arrTerms is defined as Array with 0 Dimension, an Array with NO elements at all.

In the loop, whenever an element needs to be added, the following happens:
* i, acting as pointer to the last array element is incremented
* The array is redimensioned - (ReDim) while preserving its contents (Preserve)
* The newly created last element of the array gets assigned a value (Trim(c.Value)).

Hope this helps

Felix


2015-02-07 11:18:27

Chris

I had to do this sort of thing for a grammar checking application. Whilst the "manual" search-and-replace command in Excel tells the user how many replacements have been made, the Replace (or Find) method doesn't appear to return that information. So I had to resort to a more long winded process of stepping through every cell in the relevant range. Works OK, but a simpler approach would be nice.Any thoughts on the best way to track the number of replacements made?


2015-02-07 08:52:42

awyatt

Keith: The purpose is to grab the contents of cells D1:D9 and stuff them into the "terms" array. In other words, D1:D9, before you run the macro, should have the terms you want removed from the range of cells being processed.

The code you cite ignores any blank cells in D1:D9 and it trims any leading and trailing spaces from the terms.

The ReDim (which might be the part for which you need explanation) simply makes the array larger for each term being stuffed into the array.

Hope that helps.


2015-02-07 08:42:26

Keith Ross

Allen
Thanks for this tip, it deals with a problem I've just been wrestling with, so thanks.
I'd be grateful if you could explain the purpose of the following section from your second example, as I don't understand it

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

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.