How to compare data in two columns to find duplicates in Excel (213367)



The information in this article applies to:

  • Microsoft Excel 2000
  • Microsoft Excel 2002
  • Microsoft Office Excel 2003

This article was previously published under Q213367

SUMMARY

This article describes two methods you can use to compare data in two Microsoft Excel worksheet columns and find duplicate entries.

MORE INFORMATION

Method 1: Use a Worksheet Formula

To use a worksheet formula to compare the data in two columns, follow these steps:
  1. Start Excel.
  2. In a new worksheet, enter the following data (leave column B empty):
    A1: 1   B1:     C1: 3
    A2: 2   B2:     C2: 5
    A3: 3   B3:     C3: 8
    A4: 4   B4:     C4: 2
    A5: 5   B5:     C5: 0
    					
  3. Type the following formula in cell B1:

    =IF(ISERROR(MATCH(A1,$C$1:$C$5,0)),"",A1)

  4. Select cells B1:B5.
  5. On the Edit menu, point to Fill, and then click Down.

    The duplicate numbers are displayed in column B, as in the following example:
       A1: 1   B1:     C1: 3
       A2: 2   B2: 2   C2: 5
       A3: 3   B3: 3   C3: 8
       A4: 4   B4:     C4: 2
       A5: 5   B5: 5   C5: 0
    					

Method 2: Use a Visual Basic Macro

Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific requirements. To use a Visual Basic macro to compare the data in two columns, use the steps in the following example:
  1. Start Excel.
  2. Press ALT+F11 to start the Visual Basic editor.
  3. On the Insert menu, click Module.
  4. Enter the following code in a module sheet:
    Sub Find_Matches()
        Dim CompareRange As Variant, x As Variant, y As Variant
        ' Set CompareRange equal to the range to which you will
        ' compare the selection.
        Set CompareRange = Range("C1:C5")
        ' NOTE: If the compare range is located on another workbook
        ' or worksheet, use the following syntax.
        ' Set CompareRange = Workbooks("Book2"). _
        '   Worksheets("Sheet2").Range("C1:C5")
        '
        ' Loop through each cell in the selection and compare it to
        ' each cell in CompareRange.
        For Each x In Selection
            For Each y In CompareRange
                If x = y Then x.Offset(0, 1) = x
            Next y
        Next x
    End Sub
    					
  5. Press ALT+F11 to return to Microsoft Excel.
  6. Enter the following data (leave column B empty):
    A1: 1   B1:     C1: 3
    A2: 2   B2:     C2: 5
    A3: 3   B3:     C3: 8
    A4: 4   B4:     C4: 2
    A5: 5   B5:     C5: 0
    					
  7. Select the range A1:A5.
  8. On the Tools menu, point to Macro, and then click Macros.
  9. Click Find_Matches, and then click Run.
The duplicate numbers are displayed in column B. The matching numbers will be put next to the first column, as illustrated here:
   A1: 1   B1:     C1: 3
   A2: 2   B2: 2   C2: 5
   A3: 3   B3: 3   C3: 8
   A4: 4   B4:     C4: 2
   A5: 5   B5: 5   C5: 0
				

Modification Type:MinorLast Reviewed:10/11/2006
Keywords:kbdtacode kbhowto kbProgramming KB213367