ACC: Explicitly Close Recordsets to Help Prevent Database Bloat (186311)



The information in this article applies to:

  • Microsoft Access for Windows 95 7.0
  • Microsoft Access 97

This article was previously published under Q186311
Moderate: Requires basic macro, coding, and interoperability skills.

SYMPTOMS

In the versions of Microsoft Access listed at the beginning of this article, if you use Data Access Objects (DAO) to open a recordset and don't explicitly close the recordset, DAO may hold onto the memory that it used for its previous compile until the next recordset is opened.

CAUSE

Because the recordset memory is not released, each time that you loop through code, DAO may recompile, using more memory and increasing the size of the database.

RESOLUTION

To avoid consuming unnecessary resources and increasing database size, use the Close method of the Recordset object to explicitly close the Recordset's memory when you no longer require the Recordset.

If the database has increased in size because you did not use the Close Method of the Recordset object, you can subsequently reduce its size by compacting the database.

MORE INFORMATION

Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers 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 requirements. When you create a Recordset (or QueryDef) object in code, explicitly close the object when you are finished with it. Microsoft Access automatically closes Recordset and QueryDef objects under most circumstances; however, if you explicitly close the object in your code, you can avoid occasional instances when the object remains open. The following steps demonstrate closing the Recordset and QueryDef objects using DAO.
  1. Start Microsoft Access.
  2. Open the sample database Northwind.mdb.
  3. Copy the following code to a new module:
       The following sample code opens and closes a Recordset and a QueryDef
       object and displays both Recordset and QueryDef information in message
       boxes.
    
        Sub CloseObjects()
           Dim db As Database
           Dim rs As Recordset
           Dim qd As QueryDef
    
           Set db = CurrentDb
           Set rs = db.OpenRecordset("Employees", dbOpenTable)
           Set qd = db.QueryDefs("Invoices")
    
           rs.MoveLast ' Move to the last record in the Recordset.
    
           MsgBox "The Employees Recordset is open." & vbcr & _
              "The last Employee ID is " & rs![EmployeeID] & "."
    
           Msgbox "The Invoices query definition is open." & vbcr & _
              "The first field in the query is " & qd.Fields(0).Name
    
           ' Explicitly close the Recordset and QueryDef objects.
           rs.Close
           qd.Close
        End Sub
    					
  4. Run the CloseObjects subroutine.

REFERENCES

For more information about issues that can arise from leaving recordsets open in DAO please see the following articles in the Microsoft Knowledge Base:

164455 ACC: Problems Quitting Microsoft Access

164481 ACC97: Tips for Converting Applications to Using ODBCDirect


Modification Type:MinorLast Reviewed:10/11/2006
Keywords:kbprb kbProgramming KB186311