Compare 2 range and rearrange data

smanith

New Member
Joined
Apr 15, 2019
Messages
3
Hi all,
am new to excel macro VB, I have a requirement , where i have the below data:
[TABLE="width: 320"]
<colgroup><col width="64" span="5" style="width:48pt"> </colgroup><tbody>[TR]
[TD="class: xl64, width: 64"]Number[/TD]
[TD="class: xl64, width: 64"]Value[/TD]
[TD="class: xl64, width: 64"]Number[/TD]
[TD="class: xl64, width: 64"]Value[/TD]
[TD="class: xl64, width: 64"]Difference[/TD]
[/TR]
[TR]
[TD="class: xl63, align: right"][TABLE="width: 256"]
<colgroup><col width="64" span="4" style="width:48pt"> </colgroup><tbody>[TR]
[TD="class: xl66, width: 64"]Number[/TD]
[TD="class: xl66, width: 64"]Value[/TD]
[TD="class: xl66, width: 64"]Number[/TD]
[TD="class: xl66, width: 64"]Value[/TD]
[/TR]
[TR]
[TD="class: xl65, align: right"]113999[/TD]
[TD="class: xl65, align: right"]2475802[/TD]
[TD="class: xl65, align: right"]0[/TD]
[TD="class: xl65, align: right"]161717.6[/TD]
[/TR]
[TR]
[TD="class: xl65, align: right"]115000[/TD]
[TD="class: xl65, align: right"]161717.6[/TD]
[TD="class: xl65, align: right"]113902[/TD]
[TD="class: xl65, align: right"]1611615[/TD]
[/TR]
[TR]
[TD="class: xl65, align: right"]119140[/TD]
[TD="class: xl65, align: right"]21780.24[/TD]
[TD="class: xl65, align: right"]113999[/TD]
[TD="class: xl65, align: right"]2475284[/TD]
[/TR]
[TR]
[TD="class: xl65, align: right"]119150[/TD]
[TD="class: xl65, align: right"]274086.8[/TD]
[TD="class: xl65, align: right"]119140[/TD]
[TD="class: xl65, align: right"]21780.24[/TD]
[/TR]
[TR]
[TD="class: xl65, align: right"]119160[/TD]
[TD="class: xl65, align: right"]792537.1[/TD]
[TD="class: xl65, align: right"]119150[/TD]
[TD="class: xl65, align: right"]274086.8[/TD]
[/TR]
[TR]
[TD="class: xl65, align: right"]119180[/TD]
[TD="class: xl65, align: right"]349912.7[/TD]
[TD="class: xl65, align: right"]119160[/TD]
[TD="class: xl65, align: right"]792537.9[/TD]
[/TR]
[TR]
[TD="class: xl65, align: right"]119190[/TD]
[TD="class: xl65, align: right"]308752.5[/TD]
[TD="class: xl65, align: right"]119180[/TD]
[TD="class: xl65, align: right"]320793.7[/TD]
[/TR]
[TR]
[TD="class: xl65, align: right"]119210[/TD]
[TD="class: xl65, align: right"]80364[/TD]
[TD="class: xl65, align: right"]119190[/TD]
[TD="class: xl65, align: right"]308752.5[/TD]
[/TR]
[TR]
[TD="class: xl65, align: right"]119220[/TD]
[TD="class: xl65, align: right"]298546.5[/TD]
[TD="class: xl65, align: right"]119210[/TD]
[TD="class: xl65, align: right"]80364[/TD]
[/TR]
[TR]
[TD="class: xl65, align: right"]119250[/TD]
[TD="class: xl65, align: right"]791109.7[/TD]
[TD="class: xl65, align: right"]119220[/TD]
[TD="class: xl65, align: right"]298546.5[/TD]
[/TR]
[TR]
[TD="class: xl65, align: right"]119280[/TD]
[TD="class: xl65, align: right"]704297.7[/TD]
[TD="class: xl65, align: right"]119250[/TD]
[TD="class: xl65, align: right"]791109.7[/TD]
[/TR]
[TR]
[TD="class: xl65, align: right"]119330[/TD]
[TD="class: xl65, align: right"]239020[/TD]
[TD="class: xl65, align: right"]119280[/TD]
[TD="class: xl65, align: right"]704297.7[/TD]
[/TR]
[TR]
[TD="class: xl65, align: right"]180014[/TD]
[TD="class: xl65, align: right"]306944.2[/TD]
[TD="class: xl65, align: right"]119330[/TD]
[TD="class: xl65, align: right"]239020[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD="class: xl63, align: right"][/TD]
[TD="class: xl63, align: right"][/TD]
[TD="class: xl63, align: right"][/TD]
[TD="class: xl63"][/TD]
[/TR]
</tbody>[/TABLE]

Here 2 sets are there, i need to compare column1(Number) with column3(Number) and rearrange the whole table with matching Number values. For example i need the result as below:

[TABLE="width: 265"]
<colgroup><col><col span="3"></colgroup><tbody>[TR]
[TD]Number[/TD]
[TD]Value[/TD]
[TD]Number[/TD]
[TD]Value[/TD]
[/TR]
[TR]
[TD="align: right"]113999[/TD]
[TD="align: right"]2475802[/TD]
[TD="align: right"]113999[/TD]
[TD="align: right"]2475284[/TD]
[/TR]
[TR]
[TD="align: right"]115000[/TD]
[TD="align: right"]161717.6[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="align: right"]119140[/TD]
[TD="align: right"]21780.24[/TD]
[TD="align: right"]119140[/TD]
[TD="align: right"]21780.24[/TD]
[/TR]
[TR]
[TD="align: right"]119150[/TD]
[TD="align: right"]274086.8[/TD]
[TD="align: right"]119150[/TD]
[TD="align: right"]274086.8[/TD]
[/TR]
[TR]
[TD="align: right"]119160[/TD]
[TD="align: right"]792537.1[/TD]
[TD="align: right"]119160[/TD]
[TD="align: right"]792537.9[/TD]
[/TR]
[TR]
[TD="align: right"]119180[/TD]
[TD="align: right"]349912.7[/TD]
[TD="align: right"]119180[/TD]
[TD="align: right"]320793.7[/TD]
[/TR]
[TR]
[TD="align: right"]119190[/TD]
[TD="align: right"]308752.5[/TD]
[TD="align: right"]119190[/TD]
[TD="align: right"]308752.5[/TD]
[/TR]
[TR]
[TD="align: right"]119210[/TD]
[TD="align: right"]80364[/TD]
[TD="align: right"]119210[/TD]
[TD="align: right"]80364[/TD]
[/TR]
[TR]
[TD="align: right"]119220[/TD]
[TD="align: right"]298546.5[/TD]
[TD="align: right"]119220[/TD]
[TD="align: right"]298546.5[/TD]
[/TR]
[TR]
[TD="align: right"]119250[/TD]
[TD="align: right"]791109.7[/TD]
[TD="align: right"]119250[/TD]
[TD="align: right"]791109.7[/TD]
[/TR]
[TR]
[TD="align: right"]119280[/TD]
[TD="align: right"]704297.7[/TD]
[TD="align: right"]119280[/TD]
[TD="align: right"]704297.7[/TD]
[/TR]
[TR]
[TD="align: right"]119330[/TD]
[TD="align: right"]239020[/TD]
[TD="align: right"]119330[/TD]
[TD="align: right"]239020[/TD]
[/TR]
[TR]
[TD="align: right"]180014[/TD]
[TD="align: right"]306944.2[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]161717.6[/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD="align: right"]113902[/TD]
[TD="align: right"]1611615

[/TD]
[/TR]
</tbody>[/TABLE]

Could you please help me out with this? Read in the forum that it can be achieved using dictionary. But since am new here, could not proceed with it.
 

Excel Facts

Square and cube roots
The =SQRT(25) is a square root. For a cube root, use =125^(1/3). For a fourth root, use =625^(1/4).
Try this:-
NB:- This code will alter your data!!

Code:
[COLOR="Navy"]Sub[/COLOR] MG15Apr13
[COLOR="Navy"]Dim[/COLOR] Rng [COLOR="Navy"]As[/COLOR] Range, Dn [COLOR="Navy"]As[/COLOR] Range, n [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long,[/COLOR] c [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long,[/COLOR] Ray [COLOR="Navy"]As[/COLOR] Variant
[COLOR="Navy"]Set[/COLOR] Rng = Range(Range("A2"), Range("A" & Rows.Count).End(xlUp))
Ray = Rng.Offset(, 2).Resize(, 2).Value
MsgBox Ray(1, 2)
[COLOR="Navy"]With[/COLOR] CreateObject("scripting.dictionary")
.CompareMode = vbTextCompare
    [COLOR="Navy"]For[/COLOR] n = 1 To UBound(Ray, 1)
        .Item(Ray(n, 1)) = Ray(n, 2)
    [COLOR="Navy"]Next[/COLOR] n
    Rng.Offset(, 2).Resize(, 2).ClearContents

    [COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] Dn [COLOR="Navy"]In[/COLOR] Rng
        [COLOR="Navy"]If[/COLOR] .Exists(Dn.Value) [COLOR="Navy"]Then[/COLOR]
            Dn.Offset(, 2) = Dn.Value
            Dn.Offset(, 3).Value = .Item(Dn.Value)
            .Remove (Dn.Value)
        [COLOR="Navy"]End[/COLOR] If
    [COLOR="Navy"]Next[/COLOR]

Range("C" & UBound(Ray, 1) + 2).Resize(.Count, 2) = Application.Transpose(Array(.Keys, .items))
[COLOR="Navy"]End[/COLOR] With

[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]Sub[/COLOR]
Regards Mick
 
Upvote 0
Hi Mick,
Thanks you for the quick response!
I tried running your code for the below data:

[TABLE="width: 275"]
<tbody>[TR]
[TD]113999[/TD]
[TD]3131202,25[/TD]
[TD]113902[/TD]
[TD]1545898,66[/TD]
[/TR]
[TR]
[TD]119140[/TD]
[TD]4800[/TD]
[TD]113999[/TD]
[TD]3131202,13[/TD]
[/TR]
[TR]
[TD]119150[/TD]
[TD]333861,68[/TD]
[TD]119140[/TD]
[TD]4800[/TD]
[/TR]
[TR]
[TD]119160[/TD]
[TD]536733,24[/TD]
[TD]119150[/TD]
[TD]333861,68[/TD]
[/TR]
[TR]
[TD]119180[/TD]
[TD]345958,89[/TD]
[TD]119160[/TD]
[TD]536733,24[/TD]
[/TR]
[TR]
[TD]119190[/TD]
[TD]383234,08[/TD]
[TD]119180[/TD]
[TD]345958,89[/TD]
[/TR]
[TR]
[TD]119210[/TD]
[TD]77880[/TD]
[TD]119190[/TD]
[TD]383234,08[/TD]
[/TR]
[TR]
[TD]119220[/TD]
[TD]292658,4[/TD]
[TD]119210[/TD]
[TD]77880[/TD]
[/TR]
[TR]
[TD]119250[/TD]
[TD]881794,83[/TD]
[TD]119220[/TD]
[TD]292658,4[/TD]
[/TR]
[TR]
[TD]119280[/TD]
[TD]830957,84[/TD]
[TD]119250[/TD]
[TD]881794,83[/TD]
[/TR]
[TR]
[TD]119315[/TD]
[TD]42519,1[/TD]
[TD]119280
[/TD]
[TD]830957,84[/TD]
[/TR]
[TR]
[TD]119330[/TD]
[TD]235600[/TD]
[TD]119315[/TD]
[TD]16000[/TD]
[/TR]
[TR]
[TD]180018[/TD]
[TD]91840[/TD]
[TD]119330[/TD]
[TD]235600[/TD]
[/TR]
</tbody>[/TABLE]


Result i got:

[TABLE="width: 260"]
<tbody>[TR]
[TD]113999[/TD]
[TD]3131202,25[/TD]
[TD]113999[/TD]
[TD]3131202,131[/TD]
[/TR]
[TR]
[TD]119140[/TD]
[TD]4800[/TD]
[TD]119140[/TD]
[TD]4800[/TD]
[/TR]
[TR]
[TD]119150[/TD]
[TD]333861,68[/TD]
[TD]119150[/TD]
[TD]333861,68[/TD]
[/TR]
[TR]
[TD]119160[/TD]
[TD]536733,24[/TD]
[TD]119160[/TD]
[TD]536733,24[/TD]
[/TR]
[TR]
[TD]119180[/TD]
[TD]345958,89[/TD]
[TD]119180[/TD]
[TD]345958,89[/TD]
[/TR]
[TR]
[TD]119190[/TD]
[TD]383234,08[/TD]
[TD]119190[/TD]
[TD]383234,08[/TD]
[/TR]
[TR]
[TD]119210[/TD]
[TD]77880[/TD]
[TD]119210[/TD]
[TD]77880[/TD]
[/TR]
[TR]
[TD]119220[/TD]
[TD]292658,4[/TD]
[TD]119220[/TD]
[TD]292658,4[/TD]
[/TR]
[TR]
[TD]119250[/TD]
[TD]881794,83[/TD]
[TD]119250[/TD]
[TD]881794,83[/TD]
[/TR]
[TR]
[TD]119280
[/TD]
[TD]830957,84
[/TD]
[TD]113902
[/TD]
[TD]1545898,658[/TD]
[/TR]
[TR]
[TD]119315[/TD]
[TD]42519,1[/TD]
[TD]119315[/TD]
[TD]16000[/TD]
[/TR]
[TR]
[TD]119330[/TD]
[TD]235600[/TD]
[TD]119330[/TD]
[TD]235600[/TD]
[/TR]
[TR]
[TD]180018[/TD]
[TD]91840[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]

non matching numbers are in same row -highlighted in red
one of the record from second set is missing in result - highlighted in green

Could you please help?
 
Upvote 0
I could not duplicate that , but I have changed the last row variable, see if that solves the problem!!!
Code:
[COLOR="Navy"]Sub[/COLOR] MG16Apr22
[COLOR="Navy"]Dim[/COLOR] Rng [COLOR="Navy"]As[/COLOR] Range, Dn [COLOR="Navy"]As[/COLOR] Range, n [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long,[/COLOR] c [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long,[/COLOR] Ray [COLOR="Navy"]As[/COLOR] Variant, Lst [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long[/COLOR]
[COLOR="Navy"]Set[/COLOR] Rng = Range(Range("A2"), Range("A" & Rows.Count).End(xlUp))
Ray = Rng.Offset(, 2).Resize(, 2).Value
Lst = Range("A" & Rows.Count).End(xlUp).Row
[COLOR="Navy"]With[/COLOR] CreateObject("scripting.dictionary")
.CompareMode = vbTextCompare
    [COLOR="Navy"]For[/COLOR] n = 1 To UBound(Ray, 1)
        .Item(Ray(n, 1)) = Ray(n, 2)
    [COLOR="Navy"]Next[/COLOR] n
    Rng.Offset(, 2).Resize(, 2).ClearContents

    [COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] Dn [COLOR="Navy"]In[/COLOR] Rng
        [COLOR="Navy"]If[/COLOR] .Exists(Dn.Value) [COLOR="Navy"]Then[/COLOR]
            Dn.Offset(, 2) = Dn.Value
            Dn.Offset(, 3).Value = .Item(Dn.Value)
            .Remove (Dn.Value)
        [COLOR="Navy"]End[/COLOR] If
    [COLOR="Navy"]Next[/COLOR]

Range("C" & Lst + 1).Resize(.Count, 2) = Application.Transpose(Array(.Keys, .items))
[COLOR="Navy"]End[/COLOR] With
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]Sub[/COLOR]
Regards Mick
 
Upvote 0
Hi Mick,
How would i change the code if i was comparing between two list that had 2 additional column each. A-C (A is the number) and D-F (D is the number) so that when you rearrange the list the set of column moves too.
Thanks
 
Upvote 0
Try this:-
Code:
[COLOR="Navy"]Sub[/COLOR] MG26Apr57
[COLOR="Navy"]Dim[/COLOR] Rng [COLOR="Navy"]As[/COLOR] Range, Dn [COLOR="Navy"]As[/COLOR] Range, n [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long,[/COLOR] c [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long,[/COLOR] Ray [COLOR="Navy"]As[/COLOR] Variant, Lst [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long[/COLOR]
[COLOR="Navy"]Set[/COLOR] Rng = Range(Range("A2"), Range("A" & Rows.Count).End(xlUp))
Ray = Rng.Offset(, 3).Resize(, 3).Value
Lst = Range("A" & Rows.Count).End(xlUp).Row
[COLOR="Navy"]With[/COLOR] CreateObject("scripting.dictionary")
.CompareMode = vbTextCompare
    [COLOR="Navy"]For[/COLOR] n = 1 To UBound(Ray, 1)
        .Item(Ray(n, 1)) = Array(Ray(n, 2), Ray(n, 3))
    [COLOR="Navy"]Next[/COLOR] n
    Rng.Offset(, 3).Resize(, 3).ClearContents

    [COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] Dn [COLOR="Navy"]In[/COLOR] Rng
        [COLOR="Navy"]If[/COLOR] .Exists(Dn.Value) [COLOR="Navy"]Then[/COLOR]
            Dn.Offset(, 3) = Dn.Value
            Dn.Offset(, 4).Value = .Item(Dn.Value)(0)
            Dn.Offset(, 5).Value = .Item(Dn.Value)(1)
            .Remove (Dn.Value)
        [COLOR="Navy"]End[/COLOR] If
    [COLOR="Navy"]Next[/COLOR]
[COLOR="Navy"]Dim[/COLOR] K [COLOR="Navy"]As[/COLOR] Variant
c = Lst
[COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] K [COLOR="Navy"]In[/COLOR] .keys
    c = c + 1
    Cells(c, "D") = K
    Cells(c, "E") = .Item(K)(0)
    Cells(c, "F") = .Item(K)(1)
[COLOR="Navy"]Next[/COLOR] K
[COLOR="Navy"]End[/COLOR] With
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]Sub[/COLOR]
Regards Mick
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,183
Members
453,020
Latest member
Mohamed Magdi Tawfiq Emam

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