Error With ADODB RecordSet

Ark68

Well-known Member
Joined
Mar 23, 2004
Messages
4,570
Office Version
  1. 365
  2. 2016
Platform
  1. Windows
I am trying to use this code to access data in a closed workbook. It's based on a tutorial found here.

Rich (BB code):
sub test
    Dim wstoa As Worksheet
    Dim tdyr As Long
    Dim fPath As String
    Dim cn As ADODB.Connection
    Dim rs As ADODB.Recordset
  
  
    Set cn = New ADODB.Connection
    tdyr = Year(Now)
    fPath = "D:\WSOP 2020\SupportData\(" & tdyr & ") SOP Schedule.xlsm"
    cn.ConnectionString = "Provider=Microsoft.ACE.OLEDB.12.0;Data Source=fPath;Extended Properties='Excel 12.0 Macro;HDR=YES';"
    cn.Open
    Set rs = New ADODB.Recordset
    rs.ActiveConnection = cn
    rs.Source = "SELECT * FROM [ROSTER$]"
    rs.Open
    rs.Close
    cn.Close
End sub

Question 1:
I am getting an error (line in red) that suggests it cannot find the workbook "ROSTER" (error dialogue below). I checked the workbook (2022) SOP Schedule.xlsm and their is indeed a worksheet called "ROSTER", no preceeding or trailing spaces. Before I set the record set, the connection works without error. Any thoughts on why ROSTER isn't being recognized?
Question 2:
Will those code be problematic of users machines where they have not enabled the Microsoft ActiveX Data Objects 6.1 Library? Will users of this workbook need to enable it to use this code?


Error merssage:
The Microsoft Access database engine could not find the object 'ROSTER$'. Make sure the object exists and that you spell it's name and path name correctly. If 'ROSTER$' is not a local object, check your network connection or contact the server administrator."[/code]
 

Excel Facts

Workdays for a market open Mon, Wed, Friday?
Yes! Use "0101011" for the weekend argument in NETWORKDAYS.INTL or WORKDAY.INTL. The 7 digits start on Monday. 1 means it is a weekend.
I suspect my issue may be more with the connectionstring
Code:
cn.ConnectionString = "Provider=Microsoft.ACE.OLEDB.12.0;Data Source=fPath;Extended Properties='Excel 12.0 Macro;HDR=YES';"
I'm fearing that fPath isn't being applied.
 
Upvote 0
I substituted the variable fPath with the whole path and it works.
Code:
cn.ConnectionString = _
        "Provider=Microsoft.ACE.OLEDB.12.0;" & _
        "Data Source=D:/WSOP 2020/SupportData/(" & tdyr & ") SOP Schedule.xlsm;" & _
        "Extended Properties='Excel 12.0 Macro;HDR=YES';"
 
Upvote 0
You can keep the variable which is much better for readability, however, you need to include it as a variable as shown below, not write it into the string as "text".

Rich (BB code):
cn.ConnectionString = "Provider=Microsoft.ACE.OLEDB.12.0;Data Source=" & fPath & ";Extended Properties='Excel 12.0 Macro;HDR=YES';"
 
Upvote 0
Solution
Ahhh ... ok. Yeah!
Thank you so much Suat.
 
Upvote 0

Forum statistics

Threads
1,223,954
Messages
6,175,601
Members
452,658
Latest member
GStorm

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