ACC2000: Manipulating Objects with ADO May Cause Database Bloat
ID: Q199005
|
The information in this article applies to:
Advanced: Requires expert coding, interoperability, and multiuser skills.
SYMPTOMS
When you use ActiveX Data Objects (ADO) to create objects in a database,
the size of the database increases substantially during the operation.
After compacting, the size of the database is much smaller.
RESOLUTION
Use SQL Data-Definition Language (DDL) statements rather than ADO to
create or modify database objects. For example, you can use the following
procedure to work around the behavior demonstrated in the "Steps to
Reproduce Problem" section later in this article:
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
Sub CreateTables()
Dim ADOCon As New ADODB.Connection
Dim ADOCmd As New ADODB.Command
Dim MyStr As String
Dim i As Integer, j As Integer
' Use active Access connection.
Set ADOCon = CurrentProject.Connection
For i = 1 To 20
ADOCon.Execute "CREATE TABLE tblTest" & i
For j = 1 To 200
ADOCon.Execute "ALTER TABLE tblTest" _
& i & " ADD Field" & j & " Text"
Next
Next
Application.RefreshDatabaseWindow
End Sub
STATUS
Microsoft has confirmed this to be a problem in the Microsoft products listed
at the beginning of this article.
MORE INFORMATION
This behavior typically occurs when you use ADO to create or modify a large
number of database objects. The following example demonstrates this by
using ADO to create twenty tables, each with two hundred fields. In this
example, reducing the number of fields created in the example greatly
reduces the amount of database bloat.
The sample code in this article uses Microsoft ActiveX Data Objects. For this code
to run properly, you need to reference the Microsoft ActiveX Data Objects 2.1 Library.
The sample code in this article uses ADO Extensions for DDL and Security. For this code to run properly, you need to reference the Microsoft ADO Ext. 2.1 for DDL and Security.
Steps to Reproduce Problem
- Open the sample database Northwind.mdb.
- On the Tools menu, point to Database Utilities, and then click Compact and Repair Database.
- Press CTRL+G to open the Immediate window.
- Type the following in the Immediate window, and then press ENTER:
?FileLen(CurrentDb.Name)
Note that this function returns the file size in bytes of the currently opened database (Northwind.mdb). Take note of the current size.
- Create a module and type the following line in the Declarations section if it is not already there:
Option Explicit
- Type the following procedure:
Sub ADOX_CreateTables()
Dim cat As New ADOX.Catalog
Dim conn As New ADODB.Connection
Dim tbl As New ADOX.Table
Dim i As Integer, j As Integer
Set conn = CurrentProject.Connection
Set cat.ActiveConnection = conn
For i = 1 To 20
With tbl
'Create a new table
.Name = "tblTest" & i
'Add 200 text fields
For j = 1 To 200
.Columns.Append "Field" & j, adVarWChar, 50
Next j
End With
'Append the table into the Catalog's tables collection
cat.Tables.Append tbl
Set tbl = Nothing
Next
Application.RefreshDatabaseWindow
End Sub
- On the File menu, click Save Northwind. When Microsoft Access prompts you to save the module, click Yes. In the Save As dialog box, click OK to accept the default name.
- To run this procedure, type the following line in the Immediate window,and then press ENTER. It may take several minutes for this procedure to run.
ADOX_CreateTables
Note that twenty tables are added to the database, each with two hundred fields.
- Type the following line in the Immediate window, and then press ENTER:
?FileLen(CurrentDb.Name)
Note that the size of the Northwind.mdb file is now is significantly greater.
- On the taskbar click Microsoft Access (or Northwind: Database) to get back to the Database window.
- On the Tools menu, point to Database Utilities, and then click Compact and Repair Database.
- Press CTRL+G to open the Immediate window.
- Type the following in the Immediate window, and then press ENTER:
?FileLen(CurrentDb.Name)
Note that the size of the Northwind.mdb file after compacting is now closer to the size that you saw on step 4.
REFERENCES
For more information about data-definition queries, click Microsoft Access Help on the
Help menu, type "work with tables or indexes by using an SQL data-definition query" in the Office Assistant or the Answer Wizard,
and then click Search to view the topic.
Additional query words:
pra
Keywords : kbusage kbdta MdlDao
Version : WINDOWS:2000
Platform : WINDOWS
Issue type : kbbug