Share via


Recordset Object (DAO)

A Recordset object represents the records in a base table or the records that result from running a query.

Remarks

You use Recordset objects to manipulate data in a database at the record level. When you use DAO objects, you manipulate data almost entirely using Recordset objects. All Recordset objects are constructed using records (rows) and fields (columns). There are five types of Recordset objects:

  • Table-type Recordset— representation in code of a base table that you can use to add, change, or delete records from a single database table (Microsoft Access workspaces only).

  • Dynaset-type Recordset— the result of a query that can have updatable records. A dynaset-type Recordset object is a dynamic set of records that you can use to add, change, or delete records from an underlying database table or tables. A dynaset-type Recordset object can contain fields from one or more tables in a database. This type corresponds to an ODBC keyset cursor.

  • Snapshot-type Recordset— a static copy of a set of records that you can use to find data or generate reports. A snapshot-type Recordset object can contain fields from one or more tables in a database but can't be updated. This type corresponds to an ODBC static cursor.

  • Forward-only-type Recordset— identical to a snapshot except that no cursor is provided. You can only scroll forward through records. This improves performance in situations where you only need to make a single pass through a result set. This type corresponds to an ODBC forward-only cursor.

  • Dynamic-type Recordset— a query result set from one or more base tables in which you can add, change, or delete records from a row-returning query. Further, records other users add, delete, or edit in the base tables also appear in your Recordset. This type corresponds to an ODBC dynamic cursor (ODBCDirect workspaces only).

    Note

    ODBCDirect workspaces are not supported in Microsoft Access 2010. Use ADO if you want to access external data sources without using the Microsoft Access database engine.

You can choose the type of Recordset object you want to create using the type argument of the OpenRecordset method.

In a Microsoft Access workspace, if you don't specify a type, DAO attempts to create the type of Recordset with the most functionality available, starting with table. If this type isn't available, DAO attempts a dynaset, then a snapshot, and finally a forward-only type Recordset object.

In an ODBCDirect workspace, if you don't specify a type, DAO attempts to create the type of Recordset with the fastest query response, starting with forward-only. If this type isn't available, DAO attempts a snapshot, then a dynaset, and finally a dynamic- type Recordset object.

When creating a Recordset object using a non-linked TableDef object in a Microsoft Access workspace, table-type Recordset objects are created. Only dynaset-type or snapshot-type Recordset objects can be created with linked tables or tables in Microsoft Access database engine-connected ODBC databases.

A new Recordset object is automatically added to the Recordsets collection when you open the object, and is automatically removed when you close it.

Note

If you use variables to represent a Recordset object and the Database object that contains the Recordset, make sure the variables have the same scope, or lifetime. For example, if you declare a public variable that represents a Recordset object, make sure the variable that represents the Database containing the Recordset is also public, or is declared in a Sub or Function procedure using the Static keyword.

You can create as many Recordset object variables as needed. Different Recordset objects can access the same tables, queries, and fields without conflicting.

Dynaset–, snapshot–, and forward–only–type Recordset objects are stored in local memory. If there isn't enough space in local memory to store the data, the Microsoft Access database engine saves the additional data to TEMP disk space. If this space is exhausted, a trappable error occurs.

The default collection of a Recordset object is the Fields collection, and the default property of a Field object is the Value property. Use these defaults to simplify your code.

When you create a Recordset object, the current record is positioned to the first record if there are any records. If there are no records, the RecordCount property setting is 0, and the BOF and EOF property settings are True.

You can use the MoveNext, MovePrevious, MoveFirst, and MoveLast methods to reposition the current record. Forward–only–type Recordset objects support only the MoveNext method. When using the Move methods to visit each record (or "walk" through the Recordset), you can use the BOF and EOF properties to check for the beginning or end of the Recordset object.

With dynaset- and snapshot-type Recordset objects in a Microsoft Access workspace, you can also use the Find methods, such as FindFirst, to locate a specific record based on criteria. If the record isn't found, the NoMatch property is set to True. For table-type Recordset objects, you can scan records using the Seek method.

The Type property indicates the type of Recordset object created, and the Updatable property indicates whether you can change the object's records.

Information about the structure of a base table, such as the names and data types of each Field object and any Index objects, is stored in a TableDef object.

To refer to a Recordset object in a collection by its ordinal number or by its Name property setting, use any of the following syntax forms:

Recordsets(0)

Recordsets("name")

Recordsets![name]

Note

You can open a Recordset object from the same data source or database more than once, creating duplicate names in the Recordsets collection. You should assign Recordset objects to object variables and refer to them by variable name.

Example

This example demonstrates Recordset objects and the Recordsets collection by opening four different types of Recordsets, enumerating the Recordsets collection of the current Database, and enumerating the Properties collection of each Recordset.

Sub RecordsetX() 
 
   Dim dbsNorthwind As Database 
   Dim rstTable As Recordset 
   Dim rstDynaset As Recordset 
   Dim rstSnapshot As Recordset 
   Dim rstForwardOnly As Recordset 
   Dim rstLoop As Recordset 
   Dim prpLoop As Property 
 
   Set dbsNorthwind = OpenDatabase("Northwind.mdb") 
 
   With dbsNorthwind 
 
      ' Open one of each type of Recordset object. 
      Set rstTable = .OpenRecordset("Categories", _ 
         dbOpenTable) 
      Set rstDynaset = .OpenRecordset("Employees", _ 
         dbOpenDynaset) 
      Set rstSnapshot = .OpenRecordset("Shippers", _ 
         dbOpenSnapshot) 
      Set rstForwardOnly = .OpenRecordset _  
         ("Employees", dbOpenForwardOnly) 
 
      Debug.Print "Recordsets in Recordsets " & _ 
         "collection of dbsNorthwind" 
 
      ' Enumerate Recordsets collection. 
      For Each rstLoop In .Recordsets 
 
         With rstLoop 
            Debug.Print "  " & .Name 
 
            ' Enumerate Properties collection of each 
            ' Recordset object. Trap for any  
            ' properties whose values are invalid in  
            ' this context. 
            For Each prpLoop In .Properties 
               On Error Resume Next 
               If prpLoop <> "" Then Debug.Print _ 
                  "    " & prpLoop.Name & _ 
                  " = " & prpLoop 
               On Error GoTo 0 
            Next prpLoop 
 
         End With 
 
      Next rstLoop 
 
      rstTable.Close 
      rstDynaset.Close 
      rstSnapshot.Close 
      rstForwardOnly.Close 
 
      .Close 
   End With 
 
End Sub 

This example uses the OpenRecordset method to open five different Recordset objects and display their contents. The OpenRecordsetOutput procedure is required for this procedure to run.

Sub OpenRecordsetX() 
 
   Dim wrkAcc As Workspace 
   Dim wrkODBC As Workspace 
   Dim dbsNorthwind As Database 
   Dim conPubs As Connection 
   Dim rstTemp As Recordset 
   Dim rstTemp2 As Recordset 
 
   ' Open Microsoft Access and ODBCDirect workspaces, Microsoft  
   ' Access database, and ODBCDirect connection. 
   Set wrkAcc = CreateWorkspace("", "admin", "", dbUseJet) 
   Set wrkODBC = CreateWorkspace("", "admin", "", dbUseODBC) 
   Set dbsNorthwind = wrkAcc.OpenDatabase("Northwind.mdb") 
    
   ' Note: The DSN referenced below must be set to  
   '       use Microsoft Windows NT Authentication Mode to  
   '       authorize user access to the Microsoft SQL Server. 
   Set conPubs = wrkODBC.OpenConnection("", , , _ 
      "ODBC;DATABASE=pubs;DSN=Publishers") 
 
   ' Open five different Recordset objects and display the  
   ' contents of each. 
 
   Debug.Print "Opening forward-only-type recordset " & _ 
      "where the source is a QueryDef object..." 
   Set rstTemp = dbsNorthwind.OpenRecordset( _ 
      "Ten Most Expensive Products", dbOpenForwardOnly) 
   OpenRecordsetOutput rstTemp 
 
   Debug.Print "Opening read-only dynaset-type " & _ 
      "recordset where the source is an SQL statement..." 
   Set rstTemp = dbsNorthwind.OpenRecordset( _ 
      "SELECT * FROM Employees", dbOpenDynaset, dbReadOnly) 
   OpenRecordsetOutput rstTemp 
 
   ' Use the Filter property to retrieve only certain  
   ' records with the next OpenRecordset call. 
   Debug.Print "Opening recordset from existing " & _ 
      "Recordset object to filter records..." 
   rstTemp.Filter = "LastName >= 'M'" 
   Set rstTemp2 = rstTemp.OpenRecordset() 
   OpenRecordsetOutput rstTemp2 
 
   Debug.Print "Opening dynamic-type recordset from " & _ 
      "an ODBC connection..." 
   Set rstTemp = conPubs.OpenRecordset( _ 
      "SELECT * FROM stores", dbOpenDynamic) 
   OpenRecordsetOutput rstTemp 
 
   ' Use the StillExecuting property to determine when the  
   ' Recordset is ready for manipulation. 
   Debug.Print "Opening snapshot-type recordset based " & _ 
      "on asynchronous query to ODBC connection..." 
   Set rstTemp = conPubs.OpenRecordset("publishers", _ 
      dbOpenSnapshot, dbRunAsync) 
   Do While rstTemp.StillExecuting 
      Debug.Print "  [still executing...]" 
   Loop 
   OpenRecordsetOutput rstTemp 
 
   rstTemp.Close 
   dbsNorthwind.Close 
   conPubs.Close 
   wrkAcc.Close 
   wrkODBC.Close 
 
End Sub 
 
Sub OpenRecordsetOutput(rstOutput As Recordset) 
 
   ' Enumerate the specified Recordset object. 
   With rstOutput 
      Do While Not .EOF 
         Debug.Print , .Fields(0), .Fields(1) 
         .MoveNext 
      Loop 
   End With 
 
End Sub 

This example opens a dynamic-type Recordset object and enumerates its records.

Sub dbOpenDynamicX() 
 
   Dim wrkMain As Workspace 
   Dim conMain As Connection 
   Dim qdfTemp As QueryDef 
   Dim rstTemp As Recordset 
   Dim strSQL As String 
   Dim intLoop As Integer 
 
   ' Create ODBC workspace and open connection to 
   ' SQL Server database. 
   Set wrkMain = CreateWorkspace("ODBCWorkspace", _ 
      "admin", "", dbUseODBC) 
       
   ' Note: The DSN referenced below must be configured to  
   '       use Microsoft Windows NT Authentication Mode to  
   '       authorize user access to the Microsoft SQL Server.     
   Set conMain = wrkMain.OpenConnection("Publishers", _ 
      dbDriverNoPrompt, False, _ 
      "ODBC;DATABASE=pubs;DSN=Publishers") 
       
   ' Open dynamic-type recordset. 
   Set rstTemp = _ 
      conMain.OpenRecordset("authors", _ 
      dbOpenDynamic) 
 
   With rstTemp 
      Debug.Print "Dynamic-type recordset: " & .Name 
 
      ' Enumerate records. 
      Do While Not .EOF 
         Debug.Print "    " & !au_lname & ", " & _ 
            !au_fname 
         .MoveNext 
      Loop 
 
      .Close 
   End With 
 
   conMain.Close 
   wrkMain.Close 
 
End Sub 

This example opens a dynaset-type Recordset and shows the extent to which its fields are updatable.

Sub dbOpenDynasetX() 
 
   Dim dbsNorthwind As Database 
   Dim rstInvoices As Recordset 
   Dim fldLoop As Field 
 
   Set dbsNorthwind = OpenDatabase("Northwind.mdb") 
   Set rstInvoices = _ 
      dbsNorthwind.OpenRecordset("Invoices", dbOpenDynaset) 
 
   With rstInvoices 
      Debug.Print "Dynaset-type recordset: " & .Name 
 
      If .Updatable Then 
         Debug.Print "  Updatable fields:" 
 
         ' Enumerate Fields collection of dynaset-type 
         ' Recordset object, print only updatable 
         ' fields. 
         For Each fldLoop In .Fields 
            If fldLoop.DataUpdatable Then 
               Debug.Print "    " & fldLoop.Name 
            End If 
         Next fldLoop 
 
      End If 
 
      .Close 
   End With 
 
   dbsNorthwind.Close 
 
End Sub 

This example opens a forward-only-type Recordset, demonstrates its read-only characteristics, and steps through the Recordset with the MoveNext method.

Sub dbOpenForwardOnlyX() 
 
   Dim dbsNorthwind As Database 
   Dim rstEmployees As Recordset 
   Dim fldLoop As Field 
 
   Set dbsNorthwind = OpenDatabase("Northwind.mdb") 
   ' Open a forward-only-type Recordset object. Only the  
   ' MoveNext and Move methods may be used to navigate  
   ' through the recordset. 
   Set rstEmployees = _ 
      dbsNorthwind.OpenRecordset("Employees", _ 
      dbOpenForwardOnly) 
 
   With rstEmployees 
      Debug.Print "Forward-only-type recordset: " & _ 
         .Name & ", Updatable = " & .Updatable 
 
      Debug.Print "  Field - DataUpdatable" 
      ' Enumerate Fields collection, printing the Name and  
      ' DataUpdatable properties of each Field object. 
      For Each fldLoop In .Fields 
         Debug.Print "    " & _ 
            fldLoop.Name & " - " & fldLoop.DataUpdatable 
      Next fldLoop 
 
      Debug.Print "  Data" 
      ' Enumerate the recordset. 
      Do While Not .EOF 
         Debug.Print "    " & !FirstName & " " & _ 
            !LastName 
         .MoveNext 
      Loop 
 
      .Close 
   End With 
 
   dbsNorthwind.Close 
 
End Sub 
 

This example opens a snapshot-type Recordset and demonstrates its read-only characteristics.

Sub dbOpenSnapshotX() 
 
   Dim dbsNorthwind As Database 
   Dim rstEmployees As Recordset 
   Dim prpLoop As Property 
 
   Set dbsNorthwind = OpenDatabase("Northwind.mdb") 
   Set rstEmployees = _ 
      dbsNorthwind.OpenRecordset("Employees", _ 
      dbOpenSnapshot) 
 
   With rstEmployees 
      Debug.Print "Snapshot-type recordset: " & _ 
         .Name 
 
      ' Enumerate the Properties collection of the 
      ' snapshot-type Recordset object, trapping for 
      ' any properties whose values are invalid in  
      ' this context. 
      For Each prpLoop In .Properties 
         On Error Resume Next 
         Debug.Print "  " & _ 
            prpLoop.Name & " = " & prpLoop 
         On Error Goto 0 
      Next prpLoop 
 
      .Close 
   End With 
 
   dbsNorthwind.Close 
 
End Sub 

This example opens a table-type Recordset, sets its Index property, and enumerates its records.

Sub dbOpenTableX() 
 
   Dim dbsNorthwind As Database 
   Dim rstEmployees As Recordset 
 
   Set dbsNorthwind = OpenDatabase("Northwind.mdb") 
   ' dbOpenTable is default. 
   Set rstEmployees = _ 
      dbsNorthwind.OpenRecordset("Employees") 
 
   With rstEmployees 
      Debug.Print "Table-type recordset: " & .Name 
 
      ' Use predefined index. 
      .Index = "LastName" 
      Debug.Print "  Index = " & .Index 
 
      ' Enumerate records. 
      Do While Not .EOF 
         Debug.Print "    " & !LastName & ", " & _ 
            !FirstName 
         .MoveNext 
      Loop 
 
      .Close 
   End With 
 
   dbsNorthwind.Close 
 
End Sub 

The following example shows how to use the Seek method to find a record in a linked table.

Sample code provided by: Access 2010 Programmers Reference book cover The Microsoft Access 2010 Programmer’s Reference | About the Contributors

Sub TestSeek()
    ' Get the path to the external database that contains
    ' the tblCustomers table we're going to search.
    Dim strMyExternalDatabase
    Dim dbs    As DAO.Database
    Dim dbsExt As DAO.Database
    Dim rst    As DAO.Recordset
    Dim tdf    As DAO.TableDef
    
    Set dbs = CurrentDb()
    Set tdf = dbs.TableDefs("tblCustomers")
    strMyExternalDatabase = Mid(tdf.Connect, 11)
    
    'Open the database that contains the table that is linked
    Set dbsExt = OpenDatabase(strMyExternalDatabase)
    
    'Open a table-type recordset against the external table
    Set rst = dbsExt.OpenRecordset("tblCustomers", dbOpenTable)
    
    'Specify which index to search on
    rst.Index = "PrimaryKey"
    
    'Specify the criteria
    rst.Seek "=", 123
    
    'Check the result
    If rst.NoMatch Then
        MsgBox "Record not found."
    Else
        MsgBox "Customer name: " & rst!CustName
    End If
    
    rst.Close
    dbs.Close
    dbsExt.Close
    Set rst = Nothing
    Set tdf = Nothing
    Set dbs = Nothing
    
    
End Sub

The following example shows how to open a Recordset that is based on a parameter query.

Dim dbs As DAO.Database
Dim qdf As DAO.QueryDef
Dim rst As DAO.Recordset

Set dbs = CurrentDb

'Get the parameter query
Set qfd = dbs.QueryDefs("qryMyParameterQuery")

'Supply the parameter value
qdf.Parameters("EnterStartDate") = Date
qdf.Parameters("EnterEndDate") = Date + 7

'Open a Recordset based on the parameter query
Set rst = qdf.OpenRecordset()

The following example shows how to open a Recordset based on a table or a query.

Dim dbs As DAO.Database
Dim rsTable As DAO.Recordset
Dim rsQuery As DAO.Recordset

Set dbs = CurrentDb

'Open a table-type Recordset
Set rsTable = dbs.OpenRecordset("Table1", dbOpenTable)

'Open a dynaset-type Recordset using a saved query
Set rsQuery = dbs.OpenRecordset("qryMyQuery", dbOpenDynaset)

The following example shows how to open a Recordset based on a Structured Query Language (SQL) statement.

Dim dbs As DAO.Database
Dim rsSQL As DAO.Recordset
Dim strSQL As String

Set dbs = CurrentDb

'Open a snapshot-type Recordset based on an SQL statement
strSQL = "SELECT * FROM Table1 WHERE Field2 = 33"
Set rsSQL = dbs.OpenRecordset(strSQL, dbOpenSnapshot)

The following example shows how to use the FindFirst and FindNext methods to find a record in a Recordset.

Sub FindOrgName()

    Dim dbs As DAO.Database
    Dim rst As DAO.Recordset
    
    'Get the database and Recordset
    Set dbs = CurrentDb
    Set rst = dbs.OpenRecordset("tblCustomers")

    'Search for the first matching record   
    rst.FindFirst "[OrgName] LIKE '*parts*'"
    
    'Check the result
    If rst.NoMatch Then
        MsgBox "Record not found."
        GotTo Cleanup
    Else
        Do While Not rst.NoMatch
            MsgBox "Customer name: " & rst!CustName
            rst.FindNext "[OrgName] LIKE '*parts*'"
        Loop

        'Search for the next matching record
        rst.FindNext "[OrgName] LIKE '*parts*'"
    End If
   
    Cleanup:
        rst.Close
        Set rst = Nothing
        Set dbs = Nothing

End Sub

The following example shows how to copy the results of a query to a worksheet in a new Microsoft Excel workbook.

Public Sub CopyDataFromQuery( _
    xlApp As Excel.Application, _
    strQueryName As String)

    ' If the xlApp object exists
    If Not xlApp Is Nothing Then
    
        ' If the Workbook exists
        If xlApp.Workbooks.Count = 1 Then
        
            ' Create Recrodset Object from the Query
            Dim rsQuery As DAO.Recordset
            Set rsQuery = Application.CurrentDb.OpenRecordset(strQueryName)
            
            ' Get the Cells object
            Dim Cells As Object
            Set Cells = xlApp.Workbooks(1).ActiveSheet.Cells
            
            ' Copy the Data from the Query into the Sheet
            Cells.CopyFromRecordset rsQuery
            
        End If
    End If

End Sub

About the Contributors

Wrox Press is driven by the Programmer to Programmer philosophy. Wrox books are written by programmers for programmers, and the Wrox brand means authoritative solutions to real-world programming problems.