XL: How to Compare Data in Two Columns for Duplicates
ID: Q139882
|
The information in this article applies to:
-
Microsoft Excel for Windows, versions 5.0, 5.0c
-
Microsoft Excel for Windows NT, version 5.0
-
Microsoft Excel for Windows 95, versions 7.0, 7.0a
-
Microsoft Excel 97 for Windows
-
Microsoft Excel for the Macintosh, versions 5.0, 5.0a
-
Microsoft Excel 98 Macintosh Edition
SUMMARY
This article describes two methods for comparing two columns of data to
find duplicate entries between the two columns.
MORE INFORMATIONMethod 1: Use a Worksheet Formula
The following steps describe how to use a worksheet formula to compare
the data in two columns:
- 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
- Type the following formula in cell B1:
=IF(ISERROR(MATCH(A1,$C$1:$C$5,0)),"",A1)
- 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, including, but not limited to, the
implied warranties of merchantability and/or fitness for a particular
purpose. This article assumes that you are familiar with the programming
language being demonstrated and the tools used to create and debug
procedures. Microsoft support professionals 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
needs. If you have limited programming experience, you may want to contact
the Microsoft fee-based consulting line at (800) 936-5200. For more
information about the support options available from Microsoft, please see
the following page on the World Wide Web:
http://www.microsoft.com/support/supportnet/overview/overview.asp
The following steps describe how to use a Microsoft Visual Basic for
Applications macro (Sub procedure) to compare the data in two columns.
- 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
- 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
- Select the range A1:A5.
- 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
Additional query words:
8.00 XL98 XL97 XL7 XL5 match data
Keywords : kbprg kbdta kbdtacode PgmHowto xlformula KbVBA
Version : MACINTOSH:5.0,5.0a,98; WINDOWS:5.0,5.0c,7.0,7.0a; winnt:5.0
Platform : MACINTOSH WINDOWS winnt
Issue type : kbhowto
|