Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Deleting Duplicate Text Values.

Deleting Duplicate Text Values

Written by Allen Wyatt (last updated November 17, 2018)
This tip applies to Excel 97, 2000, 2002, and 2003


2

Everybody runs into the need at one time or another—to delete duplicate entries from a list of text entries. Suppose you have the text values in column A of a worksheet, and they run for about 500 rows. If you want to delete any duplicates in the list, you may be looking for the easiest way to do it.

Manually, you can use data filtering to determine the unique values. Make sure the column has a label at the top of it, then select a cell in the column. Choose Data | Filter | Advanced Filter or, in Excel 2007, display the Data tab of the ribbon and click Advanced in the Sort & Filter group. Use the controls in the resulting dialog box to specify that you want to copy the unique values to another location which you specify.

You can also use a formula to manually determine the duplicates in the list. Sort the values in the column, and then enter the following formula in cell B2:

=IF(A2=A1,"Duplicate","")

Copy the formula down to all the cells in column B that have a corresponding value in column A. Select all the values in column B and press Ctrl+C. Use the Paste Special dialog box to paste just the values into the same selected cells. You've now converted the formulas into their results. Sort the two columns according to the contents of column B, and all of your duplicate rows will be in one area. Delete these rows, and you have your finished list of unique values.

Either of these manual approaches are fast and easy, but if you routinely have to delete duplicate values from a column, a macro may be more your style. The following macro relies on the advanced data filtering, much like the earlier manual method:

Sub CreateUniqueList()
    Dim rData As Range
    Dim rTemp As Range

    Set rData = Range(Range("a1"), Range("A65536").End(xlUp))
    rData.EntireColumn.Insert
    Set rTemp = rData.Offset(0, -1)
    rData.AdvancedFilter _
        Action:=xlFilterCopy, _
        CopyToRange:=rTemp, _
        Unique:=True

    rTemp.EntireColumn.Copy _
        rData.EntireColumn
    Application.CutCopyMode = False
    rTemp.EntireColumn.Delete
    Set rData = Nothing
    Set rTemp = Nothing
End Sub

The macro creates a temporary column, uses advanced filtering to copy the unique values to that column, then deletes the original data column. The result is just unique values in column A. If you don't want your macro to use the data filtering feature of Excel, then the following macro will do the trick:

Sub DelDups()
    Dim rngSrc As Range
    Dim NumRows As Integer
    Dim ThisRow As Integer
    Dim ThatRow As Integer
    Dim ThisCol As Integer
    Dim J As Integer, K As Integer

    Application.ScreenUpdating = False
    Set rngSrc = ActiveSheet.Range(ActiveWindow.Selection.Address)

    NumRows = rngSrc.Rows.Count
    ThisRow = rngSrc.Row
    ThatRow = ThisRow + NumRows - 1
    ThisCol = rngSrc.Column

    'Start wiping out duplicates
    For J = ThisRow To (ThatRow - 1)
        If Cells(J, ThisCol) > "" Then
            For K = (J + 1) To ThatRow
                If Cells(J, ThisCol) = Cells(K, ThisCol) Then
                    Cells(K, ThisCol) = ""
                End If
            Next K
        End If
    Next J

    'Remove cells that are empty
    For J = ThatRow To ThisRow Step -1
        If Cells(J, ThisCol) = "" Then
            Cells(J, ThisCol).Delete xlShiftUp
        End If
    Next J
    Application.ScreenUpdating = True
End Sub

The macro works on a selection you make before calling it. Thus, if you need to remove duplicate cells from the range A2:A974, simply select that range and then run the macro. When the macro is complete, the duplicate cells are removed, as are any blank cells.

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 (2430) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Deleting Duplicate Text Values.

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

Creating a Mail Merge Data File

An easy way to perform a mail merge starts with creating a data file in a Word document. This tip shows how you can ...

Discover More

Age Calculation with Fields

People don't normally think of using fields to do any calculations. Even so, you can use fields to perform a simple ...

Discover More

Clearing the Print Area

Excel allows you to specify which portions of a worksheet should be printed when you send output to your printer. If you ...

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

Quickly Deleting Cells

If you need to delete a cell, the Delete key won't do it. (That only clears the contents of a cell; it doesn't delete the ...

Discover More

Deleting Blank Columns

Import data from another program, and you could end up with a lot of blank columns in your data. Here's the quickest way ...

Discover More

Checking for Duplicate Rows Based on a Range of Columns

When working with data in Excel, you might want to figure out which rows of data represent duplicates of other rows. If ...

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 two more than 7?

2018-11-17 12:40:17

Rick Rothstein

I think this more compact macro should do what your longer DelDups macro does...

Sub DelDups()
Dim R As Long, X As Long, Data As Variant
Data = Selection.Value
With CreateObject("Scripting.Dictionary")
For R = 1 To UBound(Data)
If Len(Data(R, 1)) Then .Item(Data(R, 1)) = 1
Next
Selection.ClearContents
Selection(1).Resize(.Count) = Application.Transpose(.Keys)
End With
End Sub


2018-11-17 12:38:42

Rick Rothstein

I think this more compact macro should do what your longer DelDups macro does...

Sub DelDups()
Dim R As Long, X As Long, Data As Variant
Data = Selection.Value
With CreateObject("Scripting.Dictionary")
For R = 1 To UBound(Data)
If Len(Data(R, 1)) Then .Item(Data(R, 1)) = 1
Next
Selection.ClearContents
Selection(1).Resize(.Count) = Application.Transpose(.Keys)
End With
End Sub


This Site

Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon 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.