Vlookup - pass filename to table array

VRK

New Member
Joined
Jul 21, 2009
Messages
1
Newbie here. Basic level is recording macros and pasting them together. I try to give users the ability to open any file and pass it through. Problem: I have not been able to find the vba method that passes a user’s chosen file via GetOpenFilename, into a VLOOKUP table_array. File1 is opened and cleaned up, then open File2 and clean it. Return to File1 to enter Vlookup formula and point to File2 in the table_array in columns B:G. The recorded macro line is:
ActiveCell.FormulaR1C1 = "=VLOOKUP(RC[-4],'[file2.xls]Sheet1'!C2:C7,2,FALSE)"
 

Excel Facts

Formula for Yesterday
Name Manager, New Name. Yesterday =TODAY()-1. OK. Then, use =YESTERDAY in any cell. Tomorrow could be =TODAY()+1.
Code:
Sub FilenameIntoFormula()

    Dim sFileName As String
    Dim sFilePath As String
    Dim sFilePathName As String
    
    sFilePathName = Application.GetOpenFilename("Excel Files (*.xls), *.xls")
    sFilePath = Left(sFilePathName, InStrRev(sFilePathName, "\"))
    sFileName = Right(sFilePathName, Len(sFilePathName) - InStrRev(sFilePathName, "\"))
    Range("A1").FormulaR1C1 = _
        "=VLOOKUP(RC[-4],'" & "[" & sFileName & "]" & "'!C2:C7,2,FALSE)"
End Sub
 
Upvote 0

Forum statistics

Threads
1,214,636
Messages
6,120,664
Members
448,976
Latest member
sweeberry

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