VBA vlookup from another file in another folder

lonely_hommie

New Member
Joined
Apr 18, 2019
Messages
4
I'm trying to use data from another folder for my vlookup, but I the code below can't find the file. Anytips? :(

Set table_array_Sales_Continent_New = Workbooks.Open("C:\Users\xxx\Documents\Mapping\Mapping.xlsx").Sheets("Mapping").Range("O2:P50")
 

Excel Facts

Copy a format multiple times
Select a formatted range. Double-click the Format Painter (left side of Home tab). You can paste formatting multiple times. Esc to stop
Hi & welcome to MrExcel
If you are trying to open the file it should be
Code:
Set table_array_Sales_Continent_New = Workbooks.Open("C:\Users\xxx\Documents\Mapping\Mapping.xlsx")
 
Upvote 0
Hi, thanks for helping. I am not only trying to open the file, but also use the file and the called "Mapping" within the file and use range from O2:P50 as a vlookup.
 
Upvote 0
Can you post the rest of your code?
 
Upvote 0
Thank you for helping. I hope my code makes sense.

Code:
Option Explicit
Sub TRR_Mapping_VBA()
'Application.VLOOKUP(lookup_value, table_array, column_index, range_lookup)

'=IFERROR(VLOOKUP(AF2,Mapping!O:P,2,FALSE),"GTS Misc")
'Function I used in Excel

    Dim lookfor As Range 'lookfor
    Dim table_array As Range 'table_array
    Dim varResult As Variant 'varResult
    Dim table_array_col As Integer 'table_array_col
    Dim lookFor_col As Integer 'lookFor_col
    
    Set lookfor = Range([AF2], Cells(Rows.Count, "AF").End(3))
    
    Set table_array = Workbooks.Open("C:\Users\xxx\Documents\Mapping\Mapping.xlsx").Sheets("Mapping").Range("O2:P50")
    
    table_array_col = 2  'pull data on this column
    
    varResult = Application.VLookup(lookfor.Value, table_array, table_array_col, 0)
    
    lookFor_col = 24  'lookFor.Value starting from 0/1/2/3 where to start from column
    lookfor.Offset(0, lookFor_col) = varResult
    
     MsgBox "Done"
    
End Sub
 
Upvote 0
Try
Code:
Sub TRR_Mapping_VBA()
'Application.VLOOKUP(lookup_value, table_array, column_index, range_lookup)

'=IFERROR(VLOOKUP(AF2,Mapping!O:P,2,FALSE),"GTS Misc")
'Function I used in Excel

    Dim lookfor As Range 'lookfor
    Dim table_array As Range 'table_array
    Dim varResult As Variant 'varResult
    Dim table_array_col As Integer 'table_array_col
    Dim lookFor_col As Integer 'lookFor_col
    Dim Wbk As Workbook
    
    Set lookfor = Range("AF2")
    
    Set Wbk = Workbooks.Open("C:\Users\xxx\Documents\Mapping\Mapping.xlsx")
    Set table_array = Wbk.Sheets("Mapping").Range("O2:P50")
    
    table_array_col = 2  'pull data on this column
    
    varResult = Application.vlookup(lookfor.Value, table_array, table_array_col, 0)
    
    lookFor_col = 24  'lookFor.Value starting from 0/1/2/3 where to start from column
    lookfor.Offset(0, lookFor_col) = varResult
    
     MsgBox "Done"
    
End Sub
 
Upvote 0
It Works! Had to change the below to make sure I get vlookup for all the rows.
Set lookfor = Range([AF2], Cells(Rows.Count, "AF").End(3))

Thank you so much :)
 
Upvote 0
You're welcome & thanks for the feedback
 
Upvote 0

Forum statistics

Threads
1,214,990
Messages
6,122,625
Members
449,093
Latest member
catterz66

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