VBA to delete cells ABC if cells AB are already in another array

jbesclapez

Active Member
Joined
Feb 6, 2010
Messages
275
Hello there :-

I have a list in A B and C. Let's call this array ArrayOld
I have another list in F G and H. Let's call this ArrayNew
In ArrayNew, I can have data that are not in ArrayOld.

I would like to update the data in ABC with the ones in FBH. But beware of new data...
All cells are alphanumerical data.

Example :
The Table ArrayNew will update ArrayOLD in change the TASTE of "Dog Blue" and "Fish Blue" To "No" and it will add the "Shark Blue Yes"

TABLE ARRAYOLD

<tbody>
[TD="bgcolor: #FFFFFF"] Animal [/TD]
[TD="bgcolor: #FFFFFF"] Color [/TD]
[TD="bgcolor: #FFFFFF"] Taste [/TD]

[TD="bgcolor: #FFFFFF"] Dog [/TD]
[TD="bgcolor: #FFFFFF"] Blue [/TD]
[TD="bgcolor: #FFFFFF"] Yes [/TD]

[TD="bgcolor: #FFFFFF"] Dog [/TD]
[TD="bgcolor: #FFFFFF"] White [/TD]
[TD="bgcolor: #FFFFFF"] Yes [/TD]

[TD="bgcolor: #FFFFFF"] Dog [/TD]
[TD="bgcolor: #FFFFFF"] Red [/TD]
[TD="bgcolor: #FFFFFF"] Yes [/TD]

[TD="bgcolor: #FFFFFF"] Fish [/TD]
[TD="bgcolor: #FFFFFF"] Blue [/TD]
[TD="bgcolor: #FFFFFF"] Yes [/TD]

[TD="bgcolor: #FFFFFF"] Fish [/TD]
[TD="bgcolor: #FFFFFF"] White [/TD]
[TD="bgcolor: #FFFFFF"] Yes [/TD]

[TD="bgcolor: #FFFFFF"] Fish [/TD]
[TD="bgcolor: #FFFFFF"] Red [/TD]
[TD="bgcolor: #FFFFFF"] Yes [/TD]

[TD="bgcolor: #FFFFFF"] Turtle [/TD]
[TD="bgcolor: #FFFFFF"] Blue [/TD]
[TD="bgcolor: #FFFFFF"] Yes [/TD]

[TD="bgcolor: #FFFFFF"] Turtle [/TD]
[TD="bgcolor: #FFFFFF"] White [/TD]
[TD="bgcolor: #FFFFFF"] Yes [/TD]

[TD="bgcolor: #FFFFFF"] Turtle [/TD]
[TD="bgcolor: #FFFFFF"] Red [/TD]
[TD="bgcolor: #FFFFFF"] Yes [/TD]

</tbody>

TABLE ARRAYNEW

<tbody>
[TD="bgcolor: #FFFFFF"] Animal [/TD]
[TD="bgcolor: #FFFFFF"] Color [/TD]
[TD="bgcolor: #FFFFFF"] Taste [/TD]

[TD="bgcolor: #FFFFFF"] Dog [/TD]
[TD="bgcolor: #FFFFFF"] Blue [/TD]
[TD="bgcolor: #FFFFFF"] No [/TD]

[TD="bgcolor: #FFFFFF"] Fish [/TD]
[TD="bgcolor: #FFFFFF"] Blue [/TD]
[TD="bgcolor: #FFFFFF"] No [/TD]

[TD="bgcolor: #FFFFFF"] Fish [/TD]
[TD="bgcolor: #FFFFFF"] Red [/TD]
[TD="bgcolor: #FFFFFF"] Yes [/TD]

[TD="bgcolor: #FFFFFF"] Turtle [/TD]
[TD="bgcolor: #FFFFFF"] Blue [/TD]
[TD="bgcolor: #FFFFFF"] Yes [/TD]

[TD="bgcolor: #FFFFFF"] Shark [/TD]
[TD="bgcolor: #FFFFFF"] Blue [/TD]
[TD="bgcolor: #FFFFFF"] Yes [/TD]

</tbody>

RESULT EXPECTED

<tbody>
[TD="bgcolor: #FFFFFF"] Animal [/TD]
[TD="bgcolor: #FFFFFF"] Color [/TD]
[TD="bgcolor: #FFFFFF"] Taste [/TD]

[TD="bgcolor: #FFFFFF"] Dog [/TD]
[TD="bgcolor: #FFFFFF"] Blue [/TD]
[TD="bgcolor: #FFFFFF"] No [/TD]

[TD="bgcolor: #FFFFFF"] Dog [/TD]
[TD="bgcolor: #FFFFFF"] White [/TD]
[TD="bgcolor: #FFFFFF"] Yes [/TD]

[TD="bgcolor: #FFFFFF"] Dog [/TD]
[TD="bgcolor: #FFFFFF"] Red [/TD]
[TD="bgcolor: #FFFFFF"] Yes [/TD]

[TD="bgcolor: #FFFFFF"] Fish [/TD]
[TD="bgcolor: #FFFFFF"] Blue [/TD]
[TD="bgcolor: #FFFFFF"] No [/TD]

[TD="bgcolor: #FFFFFF"] Fish [/TD]
[TD="bgcolor: #FFFFFF"] White [/TD]
[TD="bgcolor: #FFFFFF"] Yes [/TD]

[TD="bgcolor: #FFFFFF"] Fish [/TD]
[TD="bgcolor: #FFFFFF"] Red [/TD]
[TD="bgcolor: #FFFFFF"] Yes [/TD]

[TD="bgcolor: #FFFFFF"] Turtle [/TD]
[TD="bgcolor: #FFFFFF"] Blue [/TD]
[TD="bgcolor: #FFFFFF"] Yes [/TD]

[TD="bgcolor: #FFFFFF"] Turtle [/TD]
[TD="bgcolor: #FFFFFF"] White [/TD]
[TD="bgcolor: #FFFFFF"] Yes [/TD]

[TD="bgcolor: #FFFFFF"] Turtle [/TD]
[TD="bgcolor: #FFFFFF"] Red [/TD]
[TD="bgcolor: #FFFFFF"] Yes [/TD]

[TD="bgcolor: #FFFFFF"] Shark [/TD]
[TD="bgcolor: #FFFFFF"] Blue [/TD]
[TD="bgcolor: #FFFFFF"] Yes [/TD]

</tbody>

Hope I am clear.

Thanks for your efforts.
 
Last edited:

Excel Facts

How to calculate loan payments in Excel?
Use the PMT function: =PMT(5%/12,60,-25000) is for a $25,000 loan, 5% annual interest, 60 month loan.
Try this for Update in columns "A,B,C"
Code:
[COLOR="Navy"]Sub[/COLOR] MG15Nov37
[COLOR="Navy"]Dim[/COLOR] RngA [COLOR="Navy"]As[/COLOR] Range, Dn [COLOR="Navy"]As[/COLOR] Range, n [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long,[/COLOR] Txt, RngF [COLOR="Navy"]As[/COLOR] Range, Ray [COLOR="Navy"]As[/COLOR] Variant, Ac [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long[/COLOR]
[COLOR="Navy"]Set[/COLOR] RngA = Range("A1", Range("A" & Rows.Count).End(xlUp))
[COLOR="Navy"]Set[/COLOR] RngF = Range("F1", Range("F" & Rows.Count).End(xlUp))
Ray = Array(RngA, RngF)
    [COLOR="Navy"]With[/COLOR] CreateObject("scripting.dictionary")
        .CompareMode = vbTextCompare
            ReDim nRay(1 To RngA.Count + RngF.Count, 1 To 3)
[COLOR="Navy"]For[/COLOR] Ac = 0 To 1
    [COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] Dn [COLOR="Navy"]In[/COLOR] Ray(Ac)
        Txt = Dn.Value & " " & Dn.Offset(, 1).Value
        [COLOR="Navy"]If[/COLOR] Not .Exists(Txt) [COLOR="Navy"]Then[/COLOR]
            n = n + 1
            nRay(n, 1) = Dn.Value: nRay(n, 2) = Dn.Offset(, 1).Value: nRay(n, 3) = Dn.Offset(, 2).Value
            .Add Txt, n
        [COLOR="Navy"]Else[/COLOR]
            nRay(.Item(Txt), 3) = Dn.Offset(, 2).Value
        [COLOR="Navy"]End[/COLOR] If
    [COLOR="Navy"]Next[/COLOR] Dn
[COLOR="Navy"]Next[/COLOR] Ac
Range("A1").Resize(.Count, 3) = nRay
[COLOR="Navy"]End[/COLOR] With
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]Sub[/COLOR]
Regards Mick
 
Upvote 0
Try this for Update in columns "A,B,C"
Code:
[COLOR=Navy]Sub[/COLOR] MG15Nov37
[COLOR=Navy]Dim[/COLOR] RngA [COLOR=Navy]As[/COLOR] Range, Dn [COLOR=Navy]As[/COLOR] Range, n [COLOR=Navy]As[/COLOR] [COLOR=Navy]Long,[/COLOR] Txt, RngF [COLOR=Navy]As[/COLOR] Range, Ray [COLOR=Navy]As[/COLOR] Variant, Ac [COLOR=Navy]As[/COLOR] [COLOR=Navy]Long[/COLOR]
[COLOR=Navy]Set[/COLOR] RngA = Range("A1", Range("A" & Rows.Count).End(xlUp))
[COLOR=Navy]Set[/COLOR] RngF = Range("F1", Range("F" & Rows.Count).End(xlUp))
Ray = Array(RngA, RngF)
    [COLOR=Navy]With[/COLOR] CreateObject("scripting.dictionary")
        .CompareMode = vbTextCompare
            ReDim nRay(1 To RngA.Count + RngF.Count, 1 To 3)
[COLOR=Navy]For[/COLOR] Ac = 0 To 1
    [COLOR=Navy]For[/COLOR] [COLOR=Navy]Each[/COLOR] Dn [COLOR=Navy]In[/COLOR] Ray(Ac)
        Txt = Dn.Value & " " & Dn.Offset(, 1).Value
        [COLOR=Navy]If[/COLOR] Not .Exists(Txt) [COLOR=Navy]Then[/COLOR]
            n = n + 1
            nRay(n, 1) = Dn.Value: nRay(n, 2) = Dn.Offset(, 1).Value: nRay(n, 3) = Dn.Offset(, 2).Value
            .Add Txt, n
        [COLOR=Navy]Else[/COLOR]
            nRay(.Item(Txt), 3) = Dn.Offset(, 2).Value
        [COLOR=Navy]End[/COLOR] If
    [COLOR=Navy]Next[/COLOR] Dn
[COLOR=Navy]Next[/COLOR] Ac
Range("A1").Resize(.Count, 3) = nRay
[COLOR=Navy]End[/COLOR] With
[COLOR=Navy]End[/COLOR] [COLOR=Navy]Sub[/COLOR]
Regards Mick


Mick. That is great.
I have double feelings : I am laughing from happiness from that but also I am soooo jealous of your skils.
Where do you find the info about the CreateObject scripting.dictionary. I could have never come up with that.
I was thinking of doing a vlookup and then Row to get the number of the row to delete... then copy paste back... but it was tricky and I was sure someone like you would have a better solution...

Thanks again.
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,181
Members
453,022
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