Microsoft KB Archive/172285

From BetaArchive Wiki
< Microsoft KB Archive
Revision as of 11:30, 21 July 2020 by X010 (talk | contribs) (Text replacement - "&" to "&")
(diff) ← Older revision | Latest revision (diff) | Newer revision → (diff)

Article ID: 172285

Article Last Modified on 1/20/2007



APPLIES TO

  • Microsoft Access 97 Standard Edition



This article was previously published under Q172285

Advanced: Requires expert coding, interoperability, and multiuser skills.


SYMPTOMS

When you use Data Access Objects (DAO) 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.

This article assumes that you are familiar with Visual Basic for Applications and with creating Microsoft Access applications using the programming tools provided with Microsoft Access. For more information about Visual Basic for Applications, please refer to the "Building Applications with Microsoft Access 97" manual.

RESOLUTION

Use SQL Data Definition Language (DDL) statements rather than DAO 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:

   Sub CreateTables()
      Dim db As Database
      Dim sql As String
      Dim i As Integer, j As Integer

      Set db = CurrentDb()
      For i = 1 To 20
         sql = "CREATE TABLE Table" & i & " ("
         For j = 1 To 200
            sql = sql & "Field" & j & " TEXT,"
         Next
         sql = Left$(sql, Len(sql) - 1) & ");"
         db.Execute sql
      Next
      Application.RefreshDatabaseWindow

   End Sub
                

STATUS

Microsoft has confirmed this to be a problem in Microsoft Access 97.

MORE INFORMATION

This behavior typically occurs when using DAO to create or modify a large number of database objects. The following example demonstrates this by using DAO 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.

Steps to Reproduce Problem


  1. Open the sample database Northwind.mdb.
  2. On the Tools menu, point to Database Utilities, and then click Compact Database.
  3. Press CTRL+G to open the Debug window.
  4. Type the following in the Debug window, and then press ENTER:

    ?FileLen(CurrentDb.Name)

    This function returns the file size in bytes of the currently opened database (Northwind.mdb). The file size of an unmodified copy of Northwind.mdb is approximately 1,546,240 bytes.
  5. Create a module and type the following line in the Declarations section if it is not already there:

            Option Explicit
                            
  6. Type the following procedure:

            Sub CreateTables()
              Dim db As Database
              Dim t As TableDef
              Dim f As Field
              Dim i As Integer, j As Integer
    
              Set db = CurrentDb()
              For i = 1 To 20
                 Set t = db.CreateTableDef("Table" & i)
                 For j = 1 To 200
                    Set f = t.CreateField("Field" & j)
                    f.Type = dbText
                    f.size = 50
                    t.Fields.Append f
                 Next
                 db.TableDefs.Append t
              Next
              Application.RefreshDatabaseWindow
            End Sub
                            
  7. On the Debug menu, click Compile And Save All Modules. When Microsoft Access prompts you for the name of the module, click OK to accept the default name.
  8. To run this procedure, type the following line in the Debug window, and then press ENTER. It may take several minutes for this procedure to run.

            CreateTables
                            


    Note that twenty tables are added to the database, each with two hundred fields.

  9. Type the following line in the Debug window, and then press ENTER:

    ?FileLen(CurrentDb.Name)

    Note that the file size of Northwind.mdb is now reported to be more than 52 megabytes.
  10. Press F11 to view the Database window.
  11. On the Tools menu, point to Database Utilities, and then click Compact Database.
  12. Press CTRL+G to open the Debug window.
  13. Type the following in the Debug window, and then press ENTER:

    ?FileLen(CurrentDb.Name)

    Note that the file size of Northwind.mdb after compacting is reported to be 1,898,496 bytes.


REFERENCES

For more information about DDL queries, search the Help Index for "data-definition queries," or ask the Microsoft Access 97 Office Assistant.

Keywords: kbbug kbusage KB172285