How to compare two sheets and output differences AND similarities? VBA

aNobleNoob

New Member
Joined
Aug 8, 2019
Messages
1
I have a code that takes two sheets, compares them, and outputs the matches to another sheet. The code works fine but the only problem is that it outputs matches that are from any column. For example; if column A equals "Cab" in sheet 1 & column A equals "Cab" in sheet 2, it outputs the row as a match. What I'm trying to have the code do is check for a FULL ROW match, so that if every value in all columns of a row matches the entire row of the other sheet, then output those rows.
My current code:
<code style="margin: 0px; padding: 0px; border: 0px; font-style: inherit; font-variant: inherit; font-weight: inherit; font-stretch: inherit; line-height: inherit; font-family: Consolas, Menlo, Monaco, "Lucida Console", "Liberation Mono", "DejaVu Sans Mono", "Bitstream Vera Sans Mono", "Courier New", monospace, sans-serif; vertical-align: baseline; box-sizing: inherit; white-space: inherit;">Sub CompareSolve()
Dim i As Long
Dim j As Long
Dim n As Long
Dim ar As Variant

ar
= Sheet2.Cells(10, 1).CurrentRegion.Value

With CreateObject("Scripting.Dictionary")
.CompareMode = 1
For i = 2 To UBound(ar, 1)
.Item(ar(i, 1)) = Empty
Next

ar
= Sheet1.Cells(10, 1).CurrentRegion.Value
n
= 1

For i = 2 To UBound(ar, 1)
If .exists(ar(i, 1)) Then
n
= n + 1
For j = 1 To UBound(ar, 2)
ar
(n, j) = ar(i, j)
Next j
End If
Next i
End With
Sheet3
.Cells(10, 8).Resize(n, UBound(ar, 2)).Value = ar
End Sub</code>Any ideas on how I can modify this to work?
 

Excel Facts

How to change case of text in Excel?
Use =UPPER() for upper case, =LOWER() for lower case, and =PROPER() for proper case. PROPER won't capitalize second c in Mccartney
Try this:-
Code:
Sub CompareSolve()
[COLOR="Navy"]Dim[/COLOR] i [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long[/COLOR]
[COLOR="Navy"]Dim[/COLOR] j [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long[/COLOR]
[COLOR="Navy"]Dim[/COLOR] n [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long[/COLOR]
[COLOR="Navy"]Dim[/COLOR] ar [COLOR="Navy"]As[/COLOR] Variant
[COLOR="Navy"]Dim[/COLOR] Txt [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]String[/COLOR]
[COLOR="Navy"]Dim[/COLOR] Ac [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long[/COLOR]
 ar = Sheet2.Cells(10, 1).CurrentRegion.Value

[COLOR="Navy"]With[/COLOR] CreateObject("Scripting.Dictionary")
.CompareMode = 1
    [COLOR="Navy"]For[/COLOR] i = 2 To UBound(ar, 1)
      Txt = ""
        [COLOR="Navy"]For[/COLOR] Ac = 1 To UBound(ar, 2)
            Txt = Txt & "," & ar(i, Ac)
        [COLOR="Navy"]Next[/COLOR] Ac
        .Item(Txt) = Empty
    [COLOR="Navy"]Next[/COLOR]
 
 ar = Sheet1.Cells(10, 1).CurrentRegion.Value
 
[COLOR="Navy"]For[/COLOR] i = 2 To UBound(ar, 1)
    Txt = ""
    [COLOR="Navy"]For[/COLOR] Ac = 1 To UBound(ar, 2)
            Txt = Txt & "," & ar(i, Ac)
    [COLOR="Navy"]Next[/COLOR] Ac
    [COLOR="Navy"]If[/COLOR] .exists(Txt) [COLOR="Navy"]Then[/COLOR]
        n = n + 1
        [COLOR="Navy"]For[/COLOR] j = 1 To UBound(ar, 2)
            ar(n, j) = ar(i, j)
        [COLOR="Navy"]Next[/COLOR] j
    [COLOR="Navy"]End[/COLOR] If
[COLOR="Navy"]Next[/COLOR] i
[COLOR="Navy"]End[/COLOR] With
 Sheet3.Cells(10, 8).Resize(n, UBound(ar, 2)).Value = ar
Regards Mick
 
Upvote 0

Forum statistics

Threads
1,214,925
Messages
6,122,303
Members
449,078
Latest member
nonnakkong

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top