VLookup across Worksheets

dlo1503

New Member
Joined
Feb 24, 2020
Messages
21
Office Version
  1. 365
Platform
  1. Windows
Hi,

I am trying to write a code to perform a constantly running vlookup. I need the code to search for a value (Sheet2, Cell B3) in a table in a different sheet (Sheet 1, cells b2:AJ) . The corresponding value will appear in Column B and I would like it to return the values from Sheet 1 columns G:AJ into Sheet 2 cells a12:a21, b12:b21 and c12:c21.

The value to search (Sheet2 Cell B3) will change so I need the code to run automatically. If a value cannot be matched return a text box with a message "Part has not been done before"
The table I am sourcing data from in Sheet 1 will get longer so as opposed for searching forever in column AJ I would like it to search until the last row.

Any help is greatly appreciated

Thanks
Daniel
 

Excel Facts

Back into an answer in Excel
Use Data, What-If Analysis, Goal Seek to find the correct input cell value to reach a desired result
Try this. Put the code in the sheet events.

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
  Dim f As Range
  
  If Not Intersect(Target, Range("B3")) Is Nothing Then
    If Target.CountLarge > 1 Then Exit Sub
    Set f = Sheets("Sheet1").Range("B:B").Find(Target.Value, , xlValues, xlWhole, , , False)
    If Not f Is Nothing Then
      Range("A12").Resize(10).Value = Application.Transpose(f.Offset(, 5).Resize(1, 10).Value)
      Range("B12").Resize(10).Value = Application.Transpose(f.Offset(, 15).Resize(1, 10).Value)
      Range("C12").Resize(10).Value = Application.Transpose(f.Offset(, 25).Resize(1, 10).Value)
    Else
      MsgBox "Part has not been done before"
    End If
  End If
End Sub

SHEET EVENT
Right click the tab of the sheet you want this to work, select view code and paste the code into the window that opens up.
 
Upvote 0

Forum statistics

Threads
1,213,489
Messages
6,113,952
Members
448,535
Latest member
alrossman

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