Written by Allen Wyatt (last updated September 15, 2018)
This tip applies to Excel 97, 2000, 2002, and 2003
When you are working with a large data table, it is not uncommon for the table to contain what is essentially duplicate information. To process the information in the table, you may want to remove any of the rows you consider duplicate, thereby paring down the amount of information you need to process.
For instance, let's say that the first cell of each row contains a part number. What if you want to delete any rows that have duplicate part numbers in the first cell? If you need this solution, the following macro is for you:
Sub DelDupRows()
Dim rngSrc As Range
Dim NumRows As Integer
Dim ThisRow As Integer
Dim ThatRow As Integer
Dim ThisCol As Integer
Dim RightCol 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
RightCol = ThisCol + rngSrc.Columns.Count - 1
'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 rows with empty key cells
For J = ThatRow To ThisRow Step -1
If Cells(J, ThisCol) = "" Then
Range(Cells(J, ThisCol), _
Cells(J, RightCol)).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 rows from the range D7:G85, simply select that range and then run the macro. It removes the duplicates from the range D7:D85, and then removes all rows in D7:G85 (four columns per row) for which the cell in column D is blank.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (2108) applies to Microsoft Excel 97, 2000, 2002, and 2003.
Dive Deep into Macros! Make Excel do things you thought were impossible, discover techniques you won't find anywhere else, and create powerful automated reports. Bill Jelen and Tracy Syrstad help you instantly visualize information to make it actionable. You’ll find step-by-step instructions, real-world case studies, and 50 workbooks packed with examples and solutions. Check out Microsoft Excel 2019 VBA and Macros today!
Need to get rid of everything in a worksheet except the formulas? It's easier to make this huge change than you think it is.
Discover MoreIf 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 MoreWant to delete a bunch of rows in a worksheet based on the value in a certain cell of each row? There are a couple of ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2018-10-03 12:22:47
Willy Vanhaelen
@Michael
Whether you do the Y loop top to borttom or reverse doesn't matter.
@Barry
You probably didn't test the macro because then you would have found it working quite well. In the figure herafter I explain how it works. There is even a possibility to increase the speed: simply insert "Exit For" just before the "End If" line. When the Y loop deletes a duplicate the row bolow takes its place but that has already been tested so it has no sence to continue the loop.
(see Figure 1 below)

Figure 1.
2018-09-24 03:46:34
Michael (Micky) Avidan
@Barry,
Try:
-----------------------------
For Y = X-1 To 1 Strp -1
-----------------------------
Micky
2018-09-23 07:17:56
Barry
@Willy
I think this has a bug in it. When you delete the row everything below moves up 1 row but Y doesn't adjust also so as it stands the new row Y will not be tested as a possible duplicate. It gets interesting if X is greater than Y when a row is deleted.
The code also deems a duplicate if the first column is the same even if other columns i the row are different. This may be acceptable in some circumstances but is depends on the applications definition of what is a duplicate.
2018-09-22 14:06:54
Willy Vanhaelen
You don't need three loops. In the second loop you can delete the duplicate row at once.
Here is a drastically simplified macro that does the job as well:
Sub DelDupRows()
Dim X As Long, Y As Long
Application.ScreenUpdating = False
With Selection
For X = .Rows.Count To 1 Step -1
For Y = 1 To X - 1
If .Cells(X, 1) = .Cells(Y, 1) Then
.Range(Cells(X, 1), Cells(X, .Columns.Count)).Delete xlShiftUp
End If
Next Y
Next X
End With
Application.ScreenUpdating = True
End Sub
2018-09-21 06:12:50
Thomas Papavasiliou
Thanks for your tips. An option for keeping the first or last matching data may be quite useful
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments