Noffie

Altered http://www.accessmvp.com/djsteele/DSNLessLinks.html

Aug 14th, 2018
299
0
Never
Not a member of Pastebin yet? Sign Up, it unlocks many cool features!
VB.NET 9.35 KB | None | 0 0
  1. Option Compare Database
  2.  
  3. '***************** Code Start **************
  4.  
  5. Type TableDetails
  6.     TableName As String
  7.     SourceTableName As String
  8.     Attributes As Long
  9.     IndexSQL As String
  10.     Description As Variant
  11. End Type
  12.  
  13. Sub FixConnections( _
  14.     ServerName As String, _
  15.     DatabaseName As String, _
  16.     Optional UID As String, _
  17.     Optional PWD As String _
  18. )
  19. ' This code was originally written by
  20. ' Doug Steele, MVP  [email protected]
  21. ' Modifications suggested by
  22. ' George Hepworth, MVP   [email protected]
  23. '
  24. ' You are free to use it in any application
  25. ' provided the copyright notice is left unchanged.
  26. '
  27. ' Description:  This subroutine looks for any TableDef objects in the
  28. '               database which have a connection string, and changes the
  29. '               Connect property of those TableDef objects to use a
  30. '               DSN-less connection.
  31. '               It then looks for any QueryDef objects in the database
  32. '               which have a connection string, and changes the Connect
  33. '               property of those pass-through queries to use the same
  34. '               DSN-less connection.
  35. '               This specific routine connects to the specified SQL Server
  36. '               database on a specified server.
  37. '               If a user ID and password are provided, it assumes
  38. '               SQL Server Security is being used.
  39. '               If no user ID and password are provided, it assumes
  40. '               trusted connection (Windows Security).
  41. '
  42. ' Inputs:   ServerName:     Name of the SQL Server server (string)
  43. '           DatabaseName:   Name of the database on that server (string)
  44. '           UID:            User ID if using SQL Server Security (string)
  45. '           PWD:            Password if using SQL Server Security (string)
  46. '
  47.  
  48. On Error GoTo Err_FixConnections
  49.  
  50. Dim dbCurrent As DAO.Database
  51. Dim prpCurrent As DAO.Property
  52. Dim tdfCurrent As DAO.TableDef
  53. Dim qdfCurrent As DAO.QueryDef
  54. Dim intLoop As Integer
  55. Dim intToChange As Integer
  56. Dim strConnectionString As String
  57. Dim strDescription As String
  58. Dim strQdfConnect As String
  59. Dim typNewTables() As TableDetails
  60.  
  61. ' Start by checking whether using Trusted Connection or SQL Server Security
  62.  
  63.   If (Len(UID) > 0 And Len(PWD) = 0) Or (Len(UID) = 0 And Len(PWD) > 0) Then
  64.     MsgBox "Must supply both User ID and Password to use SQL Server Security.", _
  65.       vbCritical + vbOKOnly, "Security Information Incorrect."
  66.     Exit Sub
  67.   Else
  68.     If Len(UID) > 0 And Len(PWD) > 0 Then
  69.  
  70. ' Use SQL Server Security
  71.  
  72.       strConnectionString = "ODBC;DRIVER={sql server};" & _
  73.         "DATABASE=" & DatabaseName & ";" & _
  74.         "SERVER=" & ServerName & ";" & _
  75.         "UID=" & UID & ";" & _
  76.         "PWD=" & PWD & ";"
  77.     Else
  78.  
  79. ' Use Trusted Connection
  80. ' ALTER NOFFIE, Made to look more like what was already working for us in previous server
  81.  
  82.       strConnectionString = "ODBC;DRIVER=SQL Server;" & _
  83.         "SERVER=" & ServerName & ";APP=Microsoft Office 2016;WSID=WS-001;" & _
  84.         "DATABASE=" & DatabaseName & ";" & _
  85.         "Trusted_Connection=YES;"
  86.     End If
  87.   End If
  88.  
  89.   intToChange = 0
  90.  
  91.   Set dbCurrent = DBEngine.Workspaces(0).Databases(0)
  92.  
  93. ' Build a list of all of the connected TableDefs and
  94. ' the tables to which they're connected.
  95.  
  96.   For Each tdfCurrent In dbCurrent.TableDefs
  97.     If Len(tdfCurrent.Connect) > 0 Then
  98.       If UCase$(Left$(tdfCurrent.Connect, 5)) = "ODBC;" Then
  99.         ReDim Preserve typNewTables(0 To intToChange)
  100.         typNewTables(intToChange).Attributes = tdfCurrent.Attributes
  101.         typNewTables(intToChange).TableName = tdfCurrent.Name
  102.         typNewTables(intToChange).SourceTableName = tdfCurrent.SourceTableName
  103.         typNewTables(intToChange).IndexSQL = GenerateIndexSQL(tdfCurrent.Name)
  104.         typNewTables(intToChange).Description = Null
  105.         typNewTables(intToChange).Description = tdfCurrent.Properties("Description")
  106.         intToChange = intToChange + 1
  107.       End If
  108.     End If
  109.   Next
  110.  
  111. ' Loop through all of the linked tables we found
  112.  
  113.   For intLoop = 0 To (intToChange - 1)
  114.  
  115. ' Delete the existing TableDef object
  116.  
  117.     dbCurrent.TableDefs.Delete typNewTables(intLoop).TableName
  118.  
  119. ' Create a new TableDef object, using the DSN-less connection
  120.  
  121.     Set tdfCurrent = dbCurrent.CreateTableDef(typNewTables(intLoop).TableName)
  122.     tdfCurrent.Connect = strConnectionString
  123.  
  124. ' Unfortunately, I'm current unable to test this code,
  125. ' but I've been told trying this line of code is failing for most people...
  126. ' If it doesn't work for you, just leave it out.
  127.  
  128. ' ALTER NOFFIE I did what the comment above says and commented this line out
  129. '    tdfCurrent.Attributes = typNewTables(intLoop).Attributes
  130.  
  131.     tdfCurrent.SourceTableName = typNewTables(intLoop).SourceTableName
  132.     dbCurrent.TableDefs.Append tdfCurrent
  133.  
  134. ' Where it existed, add the Description property to the new table.
  135.  
  136.     If IsNull(typNewTables(intLoop).Description) = False Then
  137.       strDescription = CStr(typNewTables(intLoop).Description)
  138.       Set prpCurrent = tdfCurrent.CreateProperty("Description", dbText, strDescription)
  139.       tdfCurrent.Properties.Append prpCurrent
  140.     End If
  141.  
  142. ' Where it existed, create the __UniqueIndex index on the new table.
  143.  
  144.     If Len(typNewTables(intLoop).IndexSQL) > 0 Then
  145.       dbCurrent.Execute typNewTables(intLoop).IndexSQL, dbFailOnError
  146.     End If
  147.   Next
  148.  
  149. ' Loop through all the QueryDef objects looked for pass-through queries to change.
  150. ' Note that, unlike TableDef objects, you do not have to delete and re-add the
  151. ' QueryDef objects: it's sufficient simply to change the Connect property.
  152. ' The reason for the changes to the error trapping are because of the scenario
  153. ' described in Addendum 6 below.
  154.  
  155.   For Each qdfCurrent In dbCurrent.QueryDefs
  156.     On Error Resume Next
  157.     strQdfConnect = qdfCurrent.Connect
  158.     On Error GoTo Err_FixConnections
  159.     If Len(strQdfConnect) > 0 Then
  160.       If UCase$(Left$(qdfCurrent.Connect, 5)) = "ODBC;" Then
  161.         qdfCurrent.Connect = strConnectionString
  162.       End If
  163.     End If
  164.     strQdfConnect = vbNullString
  165.   Next qdfCurrent
  166.  
  167. End_FixConnections:
  168.   Set tdfCurrent = Nothing
  169.   Set dbCurrent = Nothing
  170.   Exit Sub
  171.  
  172. Err_FixConnections:
  173. ' Specific error trapping added for Error 3291
  174. ' (Syntax error in CREATE INDEX statement.), since that's what many
  175. ' people were encountering with the old code.
  176. ' Also added error trapping for Error 3270 (Property Not Found.)
  177. ' to handle tables which don't have a description.
  178.  
  179.   Select Case Err.Number
  180.     Case 3270
  181.       Resume Next
  182.     Case 3291
  183.       MsgBox "Problem creating the Index using" & vbCrLf & _
  184.         typNewTables(intLoop).IndexSQL, _
  185.         vbOKOnly + vbCritical, "Fix Connections"
  186.       Resume End_FixConnections
  187.     Case 18456
  188.       MsgBox "Wrong User ID or Password.", _
  189.         vbOKOnly + vbCritical, "Fix Connections"
  190.       Resume End_FixConnections
  191.     Case Else
  192.       MsgBox Err.Description & " (" & Err.Number & ") encountered", _
  193.         vbOKOnly + vbCritical, "Fix Connections"
  194.       Resume End_FixConnections
  195.   End Select
  196.  
  197. End Sub
  198.  
  199. Function GenerateIndexSQL(TableName As String) As String
  200. ' This code was originally written by
  201. ' Doug Steele, MVP  [email protected]
  202. ' Modifications suggested by
  203. ' George Hepworth, MVP   [email protected]
  204. '
  205. ' You are free to use it in any application,
  206. ' provided the copyright notice is left unchanged.
  207. '
  208. ' Description: Linked Tables should have an index __uniqueindex.
  209. '              This function looks for that index in a given
  210. '              table and creates an SQL statement which can
  211. '              recreate that index.
  212. '              (There appears to be no other way to do this!)
  213. '              If no such index exists, the function returns an
  214. '              empty string ("").
  215. '
  216. ' Inputs:   TableDefObject: Reference to a Table (TableDef object)
  217. '
  218. ' Returns:  An SQL string (or an empty string)
  219. '
  220.  
  221. On Error GoTo Err_GenerateIndexSQL
  222.  
  223. Dim dbCurr As DAO.Database
  224. Dim idxCurr As DAO.Index
  225. Dim fldCurr As DAO.Field
  226. Dim strSQL As String
  227. Dim tdfCurr As DAO.TableDef
  228.  
  229.   Set dbCurr = CurrentDb()
  230.   Set tdfCurr = dbCurr.TableDefs(TableName)
  231.  
  232.   If tdfCurr.Indexes.Count > 0 Then
  233.  
  234. ' Ensure that there's actually an index named
  235. ' "__UnigueIndex" in the table
  236.  
  237.     On Error Resume Next
  238.     Set idxCurr = tdfCurr.Indexes("__uniqueindex")
  239.     If Err.Number = 0 Then
  240.       On Error GoTo Err_GenerateIndexSQL
  241.  
  242. ' Loop through all of the fields in the index,
  243. ' adding them to the SQL statement
  244.  
  245.       If idxCurr.Fields.Count > 0 Then
  246.         strSQL = "CREATE INDEX __UniqueIndex ON [" & TableName & "] ("
  247.         For Each fldCurr In idxCurr.Fields
  248.           strSQL = strSQL & "[" & fldCurr.Name & "], "
  249.         Next
  250.  
  251. ' Remove the trailing comma and space
  252.  
  253.         strSQL = Left$(strSQL, Len(strSQL) - 2) & ")"
  254.       End If
  255.     End If
  256.   End If
  257.  
  258. End_GenerateIndexSQL:
  259.   Set fldCurr = Nothing
  260.   Set tdfCurr = Nothing
  261.   Set dbCurr = Nothing
  262.   GenerateIndexSQL = strSQL
  263.   Exit Function
  264.  
  265. Err_GenerateIndexSQL:
  266. ' Error number 3265 is "Not found in this collection
  267. ' (in other words, either the tablename is invalid, or
  268. ' it doesn't have an index named __uniqueindex)
  269.   If Err.Number <> 3265 Then
  270.     MsgBox Err.Description & " (" & Err.Number & ") encountered", _
  271.       vbOKOnly + vbCritical, "Generate Index SQL"
  272.   End If
  273.   Resume End_GenerateIndexSQL
  274.  
  275. End Function
  276.  
  277. '************** Code End *****************
Add Comment
Please, Sign In to add comment