DSNless linked tables to MYSQL db (1 Viewer)

Dave_cha

Registered User.
Local time
Today, 16:52
Joined
Nov 11, 2002
Messages
119
Does anyone know if it's possible to create DSNless linked tables to a remote MYSQL db. i.e. Run some code when opening an access 2002 db which will establish a connection to a MYSQL db and built a set of linked tables?

I'm trying to avoid setting up DSN connections on users pc's if possible.

Thanks,

Dave
 
Yep - its possible. What your going to need to do is use ADO to create a connection string. Once the connection string is established you can then pull recordsets, update data, insert data, etc... for the most part exactly how your would be able to with a DSN connection. Seach the forum for "ADO connenection string" and you will find a ton of references. Also - see a previous post of mine where Mission2Java posted code to connect to a BE db using an ADO connection string:

http://www.access-programmers.co.uk...hreadid=55893&highlight=ADO+connection+string

HTH,
Kev
 
Dave -

Having just reread your original post (its a tad early on the East Coast this morning) I dont think its possible to have the actual tables linked in the client FE as these would require a DSN but you could just follow my previous post and use an ADO connection to create recordsets which could be used exactly the same as linked tables except there wouldn't be an actual linked table object in the db window.

Also - if the problem your having is that you do not want to physically setup a DSN on each users machine then let me know cuz I have some code that will do this for you inside the Access.

HTH,
Kev
 
Thanks Kevin,

Just reading the link you sent me....could be the solution I need though I'm a novice here so it could take time.
Basically the problem is that I have numerous Access db's which are proving too slow. The eventual aim is to build VB front ends to a MYSQL backend. In the meantime I'm going to move the data to MYSQL and use the existing Access db's as a temporary front end.
The simple solution would be to create linked tables to the MYSQL db however my boss doesn't want DSN's setup on the client PC's (I have the code to automatically check the client and install a DSN).
On the other hand I don't want to recode every form esp. given that this is just an interim solution.
Do you reckon I'm chasing a viable option or just creating extra work for myself?

Dave
 
Short answer - Extra work for yourself :)

Basically - I'm going to assume these slow apps are split FE/BE Access db's running over a network access by multiple user? Are you basing your forms recordsource on tables or on querydefs with exact criteria to limit returned data? this will help speed up the app? If you've done everything you can to get the db running as fast as possible and its still too slow then you do need to move to a larger RDBMS (such as SQL Server, Oracle, DB2, MySQL) to increase performance. However, I'm wondering why your boss is so anti DSN as this would be the simplest way to set up your interim solution. If you can't sell him on it then your going to have to create a connection to the DB in the front end.

Probably the easiest way to create the connection to the backend would be to create the connection in a hidden form and set this form to open on the start up of the db. Then you can use this connection to create recordsets and manipulate data as needed but this is going to require a fair amount of extra work on your part. If your planning a move to a straight VB FE then your going to have to learn how to do recordsets anyway so I guess there's no time like to present to get started :D

Side Note: If you intended users are running Windows and have MS Access then this is also a viable alternative to a straight VB FE as the development time difference between to the two is quite large and a purely VB FE solution is going to require the addition of a program like Crystal Reports if your looking to do a lot of reporting (this is one of the advantages of MS Access since it has a slick reporting system built right in....

HTH,
Kev
 
Some v. good points in that last mail Kevin, thanks.

A lot of the current db's are cross linked which is causing performance to slow. I've found with testing that throwing all the data on a central sql server speeds things up considerably.
I think the push for DSNless connectivity comes down to the flexibility it allows when making changes on the network, servers etc.

I've found some code on the network which will change DSN linked tables to DSNless tables. I'll post it as soon as I've tested it.

One other thing. I've noticed that when I create a DSN linked table, the connection info. is hardcoded into the MSysobjects table making future connections independent of the DSN entry in Data Sources (ODBC). I've removed the DSN entry yet the table is still able to connect. Is my logic correct or am I missing something. If I'm right users won't require the DSN entry on their PC once I've created the linked tables as the MSysobjects will hold all the connection info.

Dave
 
I've found with testing that throwing all the data on a central sql server speeds things up considerably
Gotta love large RDBMS's :cool:

Yeah - moving everything to SQL Server will definitely help performance. If you have access to SQL Server you should use stored procedures as much as possible in your business logic too as these compiled, server side queries are much quicker to run over a network from Access then dynamic SQL or even stored querydefs (depending on your network and connection).

As far as the code to change DSN linked tables to DSN-less linked tables I'd be more than interested in your findings when you get done testing as this is something I could use on a few of my apps as well (also note*) I can understand your bosses feeling that the DSN is a tad restrictive when it comes to moving/changing hardware) Also-Also: it should be pointed out that there is a ton of documentation on the fact that dropping a DSN connection and moving to pure connection strings will also increase application performance as the program no longer has to go through ODBC and search registry files, thus making transactions process faster. Here are 2 articles I remember off the top of my head but searching the web for "DSN vs DSN-less connection" will produce a lot of results:

http://www.powerasp.com/content/database/dsn_vs_dnsless.asp
http://www.4guysfromrolla.com/webtech/070399-1.shtml


Here is a good reference for connection strings also:
http://www.sqlmag.com/Articles/Index.cfm?ArticleID=39603
http://www.stardeveloper.com/articles/display.html?article=2000120101&page=1

One other thing. I've noticed that when I create a DSN linked table, the connection info. is hardcoded into the MSysobjects table making future connections independent of the DSN entry in Data Sources (ODBC). I've removed the DSN entry yet the table is still able to connect. Is my logic correct or am I missing something. If I'm right users won't require the DSN entry on their PC once I've created the linked tables as the MSysobjects will hold all the connection info.
I can't say I can really speak to this as I haven't ever really delved into this but I'll have a look and maybe in the mean time someone else with more knowledge than I will be able to comment on the MSysobjects path hardcode...

HTH,
Kev
 
Hi Kevin,

I've tested the script below and it seems to work o.k. I've set it up to access a MYSQL db but I imagine it will work equally as well with any other sql db so long as the drivers are installed on the pc.

Option Compare Database

'***************** Code Start **************

Type TableDetails
TableName As String
SourceTableName As String
Attributes As Long
IndexSQL As String
End Type

Sub FixConnections(ServerName As String, DatabaseName As String)
' This code was originally written by
' Doug Steele, MVP djsteele@canada.com
' You are free to use it in any application
' provided the copyright notice is left unchanged.
'
' Description: This subroutine looks for any TableDef objects in the
' database which have a connection string, and changes the
' Connect property of those TableDef objects to use a
' DSN-less connection.
' This specific routine connects to the specified SQL Server
' database on a specified server. It assumes trusted connection.
'
' Inputs: ServerName: Name of the SQL Server server (string)
' DatabaseName: Name of the database on that server (string)
'

On Error GoTo Err_FixConnections

Dim dbCurrent As DAO.Database
Dim intLoop As Integer
Dim intToChange As Integer
Dim tdfCurrent As DAO.TableDef
Dim typNewTables() As TableDetails

intToChange = 0

Set dbCurrent = DBEngine.Workspaces(0).Databases(0)

' Build a list of all of the connected TableDefs and
' the tables to which they're connected.

For Each tdfCurrent In dbCurrent.TableDefs
If Len(tdfCurrent.Connect) > 0 Then
ReDim Preserve typNewTables(0 To intToChange)
typNewTables(intToChange).Attributes = tdfCurrent.Attributes
typNewTables(intToChange).TableName = tdfCurrent.Name
typNewTables(intToChange).SourceTableName = tdfCurrent.SourceTableName
typNewTables(intToChange).IndexSQL = GenerateIndexSQL(tdfCurrent.Name)
intToChange = intToChange + 1
End If
Next

' Loop through all of the linked tables we found

For intLoop = 0 To (intToChange - 1)

' Delete the existing TableDef object

dbCurrent.TableDefs.Delete typNewTables(intLoop).TableName

' Create a new TableDef object, using the DSN-less connection

Set tdfCurrent = dbCurrent.CreateTableDef(typNewTables(intLoop).TableName)
tdfCurrent.Connect = "ODBC;DRIVER={MySQL ODBC 3.51 Driver};DATABASE=" & _
DatabaseName & ";SERVER=" & ServerName & _
";UID=pcuser;Password=pcuser;"
tdfCurrent.SourceTableName = typNewTables(intLoop).SourceTableName
dbCurrent.TableDefs.Append tdfCurrent

' Where it existed, create the __UniqueIndex index on the new table.

If Len(typNewTables(intLoop).IndexSQL) > 0 Then
dbCurrent.Execute typNewTables(intLoop).IndexSQL, dbFailOnError
End If
Next

End_FixConnections:
Set tdfCurrent = Nothing
Set dbCurrent = Nothing
Exit Sub

Err_FixConnections:
' Specific error trapping added for Error 3291
' (Syntax error in CREATE INDEX statement.), since that's what many
' people were encountering with the old code.
If Err.Number = 3291 Then
MsgBox "Problem creating the Index using" & vbCrLf & _
typNewTables(intLoop).IndexSQL, _
vbOKOnly + vbCritical, "Fix Connections"
Else
MsgBox Err.Description & " (" & Err.Number & ") encountered", _
vbOKOnly + vbCritical, "Fix Connections"
End If
Resume End_FixConnections

End Sub

Function GenerateIndexSQL(TableName As String) As String
' This code was originally written by
' Doug Steele, MVP djsteele@canada.com
' You are free to use it in any application,
' provided the copyright notice is left unchanged.
'
' Description: Linked Tables should have an index __uniqueindex.
' This function looks for that index in a given
' table and creates an SQL statement which can
' recreate that index.
' (There appears to be no other way to do this!)
' If no such index exists, the function returns an
' empty string ("").
'
' Inputs: TableDefObject: Reference to a Table (TableDef object)
'
' Returns: An SQL string (or an empty string)
'

On Error GoTo Err_GenerateIndexSQL

Dim dbCurr As DAO.Database
Dim idxCurr As DAO.Index
Dim fldCurr As DAO.Field
Dim strSQL As String
Dim tdfCurr As DAO.TableDef

Set dbCurr = CurrentDb()
Set tdfCurr = dbCurr.TableDefs(TableName)

If tdfCurr.Indexes.Count > 0 Then

' Ensure that there's actually an index named
' "__UnigueIndex" in the table

On Error Resume Next
Set idxCurr = tdfCurr.Indexes("__uniqueindex")
If Err.Number = 0 Then
On Error GoTo Err_GenerateIndexSQL

' Loop through all of the fields in the index,
' adding them to the SQL statement

If idxCurr.Fields.Count > 0 Then
strSQL = "CREATE INDEX __UniqueIndex ON [" & TableName & "] ("
For Each fldCurr In idxCurr.Fields
strSQL = strSQL & "[" & fldCurr.Name & "], "
Next

' Remove the trailing comma and space

strSQL = Left$(strSQL, Len(strSQL) - 2) & ")"
End If
End If
End If

End_GenerateIndexSQL:
Set fldCurr = Nothing
Set tdfCurr = Nothing
Set dbCurr = Nothing
GenerateIndexSQL = strSQL
Exit Function

Err_GenerateIndexSQL:
' Error number 3265 is "Not found in this collection
' (in other words, either the tablename is invalid, or
' it doesn't have an index named __uniqueindex)
If Err.Number <> 3265 Then
MsgBox Err.Description & " (" & Err.Number & ") encountered", _
vbOKOnly + vbCritical, "Generate Index SQL"
End If
Resume End_GenerateIndexSQL

End Function

'************** Code End *****************

Rgd's,

Dave

p.s. Thanks for the links in your last mail....loads of bedtime reading.
 
Hey Dave -

This is some nice code - just looking through it quickly it appears that this codes is basically looping through the existing tables and creating connection strings that represent the information usually contained in the DSN - not a bad way to go! Thanks for posting and good luck with the rest of your application...

Best Regards,
Kevin
 
Kevin,

Another quick question.

I've noticed that the UID doesn't appear in either the DSN or DSNless connection string after you've created a linked table (I'm using either the linked table manager or MSysobjects table to view the string). This means that users can't connect to the db without knowing the User name. Is this something you've seen and/or managed to fix?

Thanks,

Dave
 
Hey Dave -

When you establish a DSN you determine if your going to authenticate users by either using NT authentication or your BE RDBMS authentication. The default for this is NT authentication. When you view the connection string by clicking on a linked table in the front end you shoudl see the connection string and you should see the userid imbedded in the string (At least this is what Im seeing on my end)
This means that users can't connect to the db without knowing the User name
Guess I'm not really following your line of thought here..? I'm assuming that you WANT to only grant access to the db to those individuals you grant access to right? So if your using NT authentication then the users will be either (1) registered in NT groups that are assigned to server roles or (2) regsitered on the actual BE as users. This way you can establish permission on the db objects depending on user or group... They wont need to know the username if your using NT authentication as the users windows login ID will serve as the user name. For example: My applications that I run use NT authentication and the user opens the db and access forms, data, objects without even knowing they have logged in to the app by logging into the OS. This is also easier to manager then logging users directly into the BE since they dont need to physically enter a UID and Password (plus remember the UID and Password). Is this along the lines of what your taking about or have I totally missed the mark....?

Now - having said all that you can imbed the UID and Password in the connection string if you dont want to mess with UID and password but then your granting all of your users access to all objects without restricting anything so this can be dangerous...

HTH,
Kev
 
Thanks Kevin.

Our environments are slightly different. We don't operate an NT Domain here but instead work within a Netware tree/context.
The BE will sit on a Linux box and users will access the data using one UID and Password. The idea is that they'll never need to know ths UID & PW as it will be embedded into the linked table connection string, initially and the VB script when we migrate to a VB FE.
I'm currently using an mdw file to secure rights within the db and I have startup scripts preventing them viewing the Access window, holding down the shift key etc so I can afford to use one uid & pw to access the BE.
What I've been doing the last few days is create a DSN linked table using an existing DSN connection on my PC. This embeds the entire DSN connection string, except for the UID into the linked table. I then use the script I posted last week to convert this connection string to DSNless though again, even though the script includes the UID, it does not appear in the tables connection string.
The net result is that while I can use the linked tables on my own pc (even if I delete all my DSN connections within my Data Sources manager), as soon as another user attempts to use the db, he/she is prompted for the UID (all other parameters are available). Note: All network users already have the correct OBC driver installed they just don't have a DSN setup (the way we want it).
If you can tell me how I might edit the table connection string I would eternally grateful Kevin.

I hope this explains thing a bit better.

Dave
 

Users who are viewing this thread

Back
Top Bottom