Hi Gdub
You can link an Excel spreadsheet "on the fly" with the TransferSpreadsheet
method:
DoCmd.TransferSpreadsheet acLink, acSpreadsheetTypeExcel8, _
"ToolList", strExcelFile, True, strWorksheetName & "$"
You can use the common file dialog (see
http://www.mvps.org/access/api/api0001.htm) to allow the user to select the
file. If the name of the worksheet to be linked is variable, then it would
be elegant to provide the user with a combo box containing the available
worksheet names. The following code snippet will give you an idea of how to
do that:
========== start code ============
Private Sub txtExcelFile_AfterUpdate()
Dim oXL As Excel.Application
Dim oWkb As Excel.Workbook
Dim oSht As Excel.Worksheet
Dim sSheets As String
On Error GoTo ProcErr
cboWorkSheet.RowSource = ""
Set oXL = CreateObject("Excel.Application")
Set oWkb = oXL.Workbooks.Open(txtExcelFile, , True)
For Each oSht In oWkb.Worksheets
sSheets = sSheets & oSht.Name & ";"
Next
cboWorkSheet.RowSource = Left(sSheets, Len(sSheets) - 1)
ProcEnd:
On Error Resume Next
oWkb.Close False
oXL.Quit
Set oWkb = Nothing
Set oXL = Nothing
With cboWorkSheet
If .ListCount > 0 Then
.Value = .ItemData(0)
.SetFocus
If .ListCount > 1 Then .Dropdown
Else
.Value = Null
End If
End With
Exit Sub
ProcErr:
MsgBox Err.Description, vbOKOnly, "Error " & Err.Number
Resume ProcEnd