Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Deleting Duplicate Text Values.
Written by Allen Wyatt (last updated September 2, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
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. There are actually multiple ways you can accomplish this task in Excel.
Using the Delete Duplicates Tool
Perhaps the simplest method is to select the data from which you want to delete duplicates and then display the Data tab of the ribbon. Click the Remove Duplicates tool, in the Data Tools group. Excel displays the Remove Duplicates dialog box.
The great thing about the Remove Duplicates dialog box is that it lists the names of each column in your data. (The tool assumes that you have heading labels in the first row of your data.) You can then make sure there is a check mark next to each column you want checked for duplicates. When you click the OK button, your data in analyzed and the duplicate rows removed. (Again, duplicates are determined based on the columns selected in the Remove Duplicates dialog box.)
Using Data Filtering
Another manual method is to 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. 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.
Using a Formula
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 Paste Special 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.
Using a Macro
The 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 data filtering, much like the earlier manual method:
Sub CreateUniqueList() Dim rData As Range Dim rTemp As Range Set rData = Range(Range("a1"), Range("A1048576").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 much shorter macro will do the trick:
Sub RemoveDups() Dim rData As Range Set rData = Range(Range("a1"), Range("A1048576").End(xlUp)) rData.RemoveDuplicates Columns:=Array(1), Header:=xlYes End Sub
The key in this macro is using the RemoveDuplicates method, which relies on an array that contains the column numbers you want to check for duplicates. The macro shown here operates only on the contents of column A, but you could easily modify it to work on data in more than a single column. All you would need to do is to change rData so that it represented the larger data area and then modify the columns parameter so that it pointed to the columns you want checked:
rData.RemoveDuplicates Columns:=Array(1,4), Header:=xlYes
Another macro-based approach is to develop your own code to check the values in the data set, in this manner:
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:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12711) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Deleting Duplicate Text Values.
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!
Using Excel to maintain lists of information is not unusual. When working with the list you may need to determine how ...
Discover MoreUncovering the lowest value in a range is relatively easy; you can just use the MIN worksheet function. Discovering the ...
Discover MoreYou can use some of Excel's worksheet functions across a range or worksheets, but not all of them. One that has problems ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2019-03-11 08:10:04
David Robinson
You can write a formula to identify duplicates in a non-sorted list easily too.
=IF(COUNTIF(A$1:A1,A1)=1,A1,"")
(in R1C1) =IF(COUNTIF(R1C1:RC1,RC1)=1,RC1,"")
This counts how many entries in column A so far (i.e. starting in row 1 and going down) match the current value. If there is only 1 such case, it means the current value is the first instance in the column, and is returned.
2019-03-09 14:23:57
Allan
The "Remove Duplicates" tool is a great tool for removing duplicates in a long list of email contacts.
2019-03-09 10:10:32
You can also use a pivot table to easily remove duplicate values and create a unique list.
2019-03-09 09:31:09
Willy Vanhaelen
You can make the "much shorter macro" even shorter like this one-liner:
Sub RemoveDups()
Range("A:A").RemoveDuplicates Header:=xlYes, Columns:=Array(1)
End Sub
There is no need to search for the last used cell in column A since Excel will ignore the remaining blank cells in the column. You can make it even a little bit shorter by using the shortcut version [A:A] instead of Range("A:A").
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments