How to Compare Data in Two Columns for Duplicates

Article translations Article translations
Article ID: 139882 - View products that this article applies to.
This article was previously published under Q139882
Expand all | Collapse all

On This Page

SUMMARY

This article describes two methods for comparing two columns of data to find duplicate entries between the two columns.

MORE INFORMATION

Method 1: Use a Worksheet Formula

The following steps describe how to use a worksheet formula to compare the data in two columns:
  1. 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
  2. Type the following formula in cell B1:
    =IF(ISERROR(MATCH(A1,$C$1:$C$5,0)),"",A1)
  3. Select cells B1:B5. On the Edit menu, point to Fill, and then click Down.
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
				

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. The following steps describe how to use a Microsoft Visual Basic for Applications macro (Sub procedure) to compare the data in two columns.
  1. 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
    						
  2. In a new worksheet, enter the following data (leave column B empty):
          A1: 1     C1: 3
          A2: 2     C2: 5
          A3: 3     C3: 8
          A4: 4     C4: 2
          A5: 5     C5: 0
  3. Select the range A1:A5.
  4. On the Tools menu, click Macro, and select the macro "Find_Matches". (In Microsoft Excel 97 or Microsoft Excel 98 Macintosh Edition, click the Tools menu, point to Macro, and click Macros. Then, select the macro "Find_Matches".) Click Run to run the macro.
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
				

Properties

Article ID: 139882 - Last Review: October 11, 2006 - Revision: 2.3
APPLIES TO
  • Microsoft Excel 97 Standard Edition
  • Microsoft Excel 95 Standard Edition
  • Microsoft Excel 5.0 Standard Edition
  • Microsoft Excel 98 for Macintosh
Keywords: 
kbdtacode kbhowto kbprogramming KB139882
Retired KB Content Disclaimer
This article was written about products for which Microsoft no longer offers support. Therefore, this article is offered "as is" and will no longer be updated.

Give Feedback

 

Contact us for more help

Contact us for more help
Connect with Answer Desk for expert help.
Get more support from smallbusiness.support.microsoft.com