ACC2000: Scripting Server Objects with SQL Distributed Management Objects (SQL-DMO)
ID: Q233392
|
The information in this article applies to:
Advanced: Requires expert coding, interoperability, and multiuser skills.
This article applies only to a Microsoft Access project (.adp).
SUMMARY
When you create server-based objects such as tables and views in a Microsoft Access project, it's a good idea to document the schema of each object so that you can re-create it in the future.
If you own Microsoft SQL Server 7.0, you can use the Generate SQL Scripts functionality of SQL Server Enterprise Manager to document your work by outputting a file that you can run in SQL Server Query Analyzer or in OSQL to re-create the objects in your database. Microsoft Access 2000 does not have user-interface components that enable you to take advantage of this feature in SQL Server. However, you can write Visual Basic for Applications code using SQL Distributed Management Objects (SQL-DMO) that automates an instance of SQL Server 7.0 or the Microsoft Data Engine (MSDE) to create scripts.
MORE INFORMATION
The following code sample uses the Script method of SQL-DMO to generate a Transact-SQL command batch. You can use this command batch to re-create the following objects from any user database:
- Tables
- Views
- Stored Procedures
- Triggers
- User-Defined Data Types
- Rules
- Defaults
Note that the demonstration code generates Transact-SQL to re-create SQL Server objects only.
NOTE: The code does not save or restore user data. If you need to back up data in your SQL Server or MSDE database, use the Backup command. To do this, in an Access project, click the Tools menu, point to Database Utilities, and then click Backup.
Microsoft provides programming examples for illustration only, without warranty
either expressed or implied, including, but not limited to, the implied warranties of
merchantability and/or fitness for a particular purpose. This article assumes that you
are familiar with the programming language being demonstrated and the tools used to
create and debug procedures. Microsoft support professionals can help explain the functionality
of a particular procedure, but they will not modify these examples to provide added
functionality or construct procedures to meet your specific needs. If you have limited
programming experience, you may want to contact a Microsoft Certified Solution Provider
or the Microsoft fee-based consulting line at (800) 936-5200. For more information about
Microsoft Certified Solution Providers, please see the following page on the World Wide Web:
http://www.microsoft.com/mcsp/
For more information about the support options available from Microsoft, please see the
following page on the World Wide Web:
http://www.microsoft.com/support/supportnet/overview/overview.asp
To generate an SQL Script, follow these steps:
- Open Microsoft Access 2000, and create a new, blank database. Name it SQLScript.
NOTE: You must run the following code from an instance of Microsoft Access 2000 installed on the same computer that is running SQL Server or MSDE. You cannot use this sample to generate a script for a database that resides on a remote server.
- Create a new module and type the following line in the Declarations section if it is not already there:
Option Explicit
- On the Tools menu, click References. In the list of available references, click to select Microsoft SQLDMO Object Library. Click OK.
- Type the following procedure:
Sub ScriptDB(strLogin As String, strPwd As String, _
strDataBase As String, StrFilePath As String)
'==========================================================================
' Parameters
' -------------------------------------------------------------------------
' strLogin: The Login Name of the account you use to connect to the server
' strPwd: The Password for the account you use to connect to the server
' strDataBase: The name of the database you want to create script for
' StrFilePath: The path and filename to store the SQL file
'==========================================================================
Dim sql As Object
Dim db As Object
Dim objTrigger As Object
Dim intOptions As Long
Dim genObj
Set sql = CreateObject("SQLDMO.SQLServer")
Set db = CreateObject("SQLDMO.Database")
Set objTrigger = CreateObject("SQLDMO.Trigger")
Const sDrops As Integer = 1
Const sIncludeHeaders As Long = 131072
Const sDefault As Integer = 4
Const sAppendToFile As Integer = 256
Const sBindings As Integer = 128
' Set scripting options. Because you need to specify multiple behaviors
' for the ScriptType arguement, you use "Or" to combine these.
intOptions = sDrops Or sIncludeHeaders Or _
sDefault Or sAppendToFile Or sBindings
' Connect to local server
sql.Connect "(local)", strLogin, strPwd
Set db = sql.Databases(strDataBase, "dbo")
' Script User Defined Data Types
For Each genObj In db.UserDefinedDatatypes
genObj.Script intOptions, StrFilePath
Next
' Script Tables and Triggers, ignoring system
' tables and system generated triggers
For Each genObj In db.Tables
If genObj.SystemObject = False Then
genObj.Script intOptions, StrFilePath
For Each objTrigger In genObj.Triggers
If objTrigger.SystemObject = False Then
objTrigger.Script intOptions, StrFilePath
End If
Next
End If
Next
' Script Rules
For Each genObj In db.Rules
genObj.Script intOptions, StrFilePath
Next
' Script Defaults
For Each genObj In db.Defaults
genObj.Script intOptions, StrFilePath
Next
' Script Sprocs, ignoring system sprocs
For Each genObj In db.StoredProcedures
If genObj.SystemObject = False Then
genObj.Script intOptions, StrFilePath
End If
Next
' Script Views, ignoring system views and informational schemas
For Each genObj In db.Views
If genObj.SystemObject = False Then
genObj.Script intOptions, StrFilePath
End If
Next
MsgBox "Finished generating SQL scripts."
End Sub
- Save the module as MyModule.
- To call the procedure, open the Immediate window, type the following line, and then press ENTER:
Call ScriptDB("UserName","Password","DatabaseName","C:\MyResults.SQL") NOTE: In this sample, replace UserName and Password with the logon account and password of a user who has permissions on the server. Replace DatabaseName with the name of the database in which you want to script objects. Replace C:\MyResults.SQL with the path and name of the file that you want the code to generate.
REFERENCESFor more information about SQL-DMO, refer to SQL Server 7.0 Books Online, which is available for download from the following Microsoft Web site:
http://support.microsoft.com/download/support/mslfiles/sqlbol.exe
Additional query words:
Keywords : kbdta AccessCS
Version : WINDOWS:2000
Platform : WINDOWS
Issue type : kbhowto
|