Vba to find text in sheet1 cell content from sheet2

satish78

Board Regular
Joined
Aug 31, 2014
Messages
218
HI Team,

I tried to find solution to my query on mrexcel forum.
unfortunately, I did not get exact solution to my query.
Here I need a macro to get the sheet2 ColumnB data into sheet1 ColumnE.
Macro to vlookup sheet2 ColumnA data in sheet1 ColumnC text if found get Sheet2 ColumnB data into Sheet1 ColumnE respectively.
Here is sample file attached.

 

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce
I understood this part:
Here I need a macro to get the sheet2 ColumnB data into sheet1 ColumnE.

But then you said:
Macro to vlookup sheet2 ColumnA data in sheet1 ColumnC text if found get Sheet2 ColumnB data into Sheet1 ColumnE respectively.
I surely do not understand the second part
 
Upvote 0
How much data will you have on sheet1 (no of rows) ?
And is the list on Sheet2 likely to get much longer or is that roughly the sort of length it will stay at.
 
Upvote 0
See if this works for you.
I had trouble with a couple of you values in Sheet2 having an ascii code 160 instead of a space hence the replace char 160.

VBA Code:
Sub TestAddData()

    Application.ScreenUpdating = False

    Dim shtData As Worksheet, shtLookup As Worksheet
    Dim rngData As Range
    Dim arrLookup As Variant
    Dim strLookup As Variant
    Dim i As Long
    
    Set shtData = Worksheets("Sheet1")
    Set shtLookup = Worksheets("Sheet2")
    
    Set rngData = shtData.Range("A1").CurrentRegion
    arrLookup = shtLookup.Range("A1").CurrentRegion.Value

    If shtData.FilterMode = True Then shtData.ShowAllData
    
    For i = 1 To UBound(arrLookup, 1)
        strLookup = arrLookup(i, 1)
        strLookup = Replace(strLookup, Chr(160), " ")
        rngData.AutoFilter Field:=3, Criteria1:="=*" & strLookup & "*", Operator:=xlAnd
        On Error Resume Next
            rngData.Columns(3).Offset(1, 2).Resize(rngData.Rows.Count - 1).SpecialCells(xlCellTypeVisible).Value = arrLookup(i, 2)
        On Error GoTo 0
        rngData.AutoFilter Field:=3
    Next i
    
    Application.ScreenUpdating = True
    
End Sub
 
Upvote 0
See if this works for you.
I had trouble with a couple of you values in Sheet2 having an ascii code 160 instead of a space hence the replace char 160.

VBA Code:
Sub TestAddData()

    Application.ScreenUpdating = False

    Dim shtData As Worksheet, shtLookup As Worksheet
    Dim rngData As Range
    Dim arrLookup As Variant
    Dim strLookup As Variant
    Dim i As Long
   
    Set shtData = Worksheets("Sheet1")
    Set shtLookup = Worksheets("Sheet2")
   
    Set rngData = shtData.Range("A1").CurrentRegion
    arrLookup = shtLookup.Range("A1").CurrentRegion.Value

    If shtData.FilterMode = True Then shtData.ShowAllData
   
    For i = 1 To UBound(arrLookup, 1)
        strLookup = arrLookup(i, 1)
        strLookup = Replace(strLookup, Chr(160), " ")
        rngData.AutoFilter Field:=3, Criteria1:="=*" & strLookup & "*", Operator:=xlAnd
        On Error Resume Next
            rngData.Columns(3).Offset(1, 2).Resize(rngData.Rows.Count - 1).SpecialCells(xlCellTypeVisible).Value = arrLookup(i, 2)
        On Error GoTo 0
        rngData.AutoFilter Field:=3
    Next i
   
    Application.ScreenUpdating = True
   
End Sub

Thanks Alex,
Working like charm.
I appreciate your understand to my query.
 
Upvote 0

Forum statistics

Threads
1,223,909
Messages
6,175,314
Members
452,634
Latest member
cpostell

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