Matching values between sheets and then replacing VBA

sjk1193

New Member
Joined
Nov 12, 2018
Messages
29
I need to search the 2nd column of the DATA tab and see if it matches the first column of the INDEX tab. If so I need to replace the 2nd column in the DATA tab with the value in the second column in the INDEX tab and then scroll through all rows of the DATA tab and do the same thing

example.

If Albert b, def in the DATA tab matches def, 2 in the INDEX tab then replace def in the DATA tab with 2


I have the following code so far but it doesnt seem to work

For i = 1 To 1000
For j = 2 To 1000
If Sheets("DATA").Cells(i, 2).Value = Sheets("INDEX").Cells(j, 1).Value Then
Range(Sheets("INDEX").Cells(j, 2)).Copy
Range(Sheets("DATA").Cells(i, 2)).Paste
Exit For
End If
Next j




DATA
[TABLE="width: 500"]
<tbody>[TR]
[TD]Alan[/TD]
[TD]abc[/TD]
[/TR]
[TR]
[TD]Alan[/TD]
[TD]def[/TD]
[/TR]
[TR]
[TD]Alan[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]Alan[/TD]
[TD]wer[/TD]
[/TR]
[TR]
[TD]Albert b[/TD]
[TD]abc[/TD]
[/TR]
[TR]
[TD]Albert b[/TD]
[TD]def[/TD]
[/TR]
[TR]
[TD]Albert b[/TD]
[TD]wer[/TD]
[/TR]
[TR]
[TD]Phillips[/TD]
[TD]rtt[/TD]
[/TR]
[TR]
[TD]Phillips[/TD]
[TD]wer[/TD]
[/TR]
[TR]
[TD]Phillips[/TD]
[TD]mnb[/TD]
[/TR]
</tbody>[/TABLE]


INDEX
[TABLE="width: 500"]
<tbody>[TR]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]abc[/TD]
[TD]1[/TD]
[/TR]
[TR]
[TD]asd[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]wer[/TD]
[TD]3[/TD]
[/TR]
[TR]
[TD]rtt[/TD]
[TD]4[/TD]
[/TR]
[TR]
[TD]asdasd[/TD]
[TD]6[/TD]
[/TR]
[TR]
[TD]mnb[/TD]
[TD]5[/TD]
[/TR]
[TR]
[TD]sdfs[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]def[/TD]
[TD]2[/TD]
[/TR]
[TR]
[TD]tyfyut[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]sdfsdf[/TD]
[TD]9[/TD]
[/TR]
</tbody>[/TABLE]
 

Excel Facts

Format cells as currency
Select range and press Ctrl+Shift+4 to format cells as currency. (Shift 4 is the $ sign).
give this a try.
Code:
Sub t()
Dim sh1 As Worksheet, sh2 As Worksheet, c As Range, fn As Range
Set sh1 = Sheets("DATA")
Set sh2 = Sheets("INDEX")
    For Each c In sh1.Range("B2", sh1.Cells(Rows.Count, 2).End(xlUp))
        If c <> "" Then
            Set fn = sh2.Range("A:A").Find(c.Value, , xlValues, xlWhole)
                If Not fn Is Nothing Then
                    c = fn.Offset(, 1).Value
                End If
        End If
    Next
End Sub
 
Last edited:
Upvote 0
How about
Code:
Sub GetMatch()
   Dim Cl As Range
   Dim Dic As Object
   
   Set Dic = CreateObject("Scripting.dictionary")
   With Sheets("index")
      For Each Cl In .Range("A2", .Range("A" & Rows.Count).End(xlUp))
         Dic.Item(Cl.Value) = Cl.Offset(, 1).Value
      Next Cl
   End With
   With Sheets("Data")
      For Each Cl In .Range("B2", .Range("B" & Rows.Count).End(xlUp))
         Cl.Value = Dic.Item(Cl.Value)
      Next Cl
   End With
End Sub
 
Upvote 0

Forum statistics

Threads
1,223,896
Messages
6,175,262
Members
452,627
Latest member
KitkatToby

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