CacheSize Property

Applies To

Dynamic-Type Recordset object, Dynaset-Type Recordset object, QueryDef object, Recordset object, Snapshot-Type Recordset object.

Description

Sets or returns the number of records retrieved from an ODBC data source that will be cached locally.

Settings and Return Values

The setting or return value is a Long value and must be between 5 and 1200, but not greater than available memory will allow. A typical value is 100. A setting of 0 turns off caching.

Remarks

Data caching improves performance if you use Recordset objects to retrieve data from a remote server. A cache is a space in local memory that holds the data most recently retrieved from the server; this is useful if users request the data again while the application is running. When users request data, the Microsoft Jet database engine checks the cache for the requested data first rather than retrieving it from the server, which takes more time. The cache only saves data that comes from an ODBC data source.

Any Microsoft Jet-connected ODBC data source, such as a linked table, can have a local cache. To create the cache, open a Recordset object from the remote data source, set the CacheSize and CacheStart properties, and then use the FillCache method, or step through the records by using the Move methods.

An ODBCDirect workspace can use a local cache. To create the cache, set the CacheSize property on a QueryDef object. On a Relation object, CacheSize is read-only and depends on the value of the QueryDef object's CacheSize property. You can't use the CacheStart property on FillCache method in an ODBCDirect workspace.

You can base the CacheSize property setting on the number of records your application can handle at one time. For example, if you're using a Recordset object as the source of the data to be displayed on screen, you could set its CacheSize property to 20 to display 20 records at one time.

The Microsoft Jet database engine requests records within the cache range from the cache, and it requests records outside the cache range from the server.

Records retrieved from the cache don't reflect concurrent changes that other users made to the source data.

To force an update of all the cached data, set the CacheSize property of the Recordset object to 0, re-set it to the size of the cache you originally requested, and then use the FillCache method.

See Also

Bookmark property, Bookmarkable property, FillCache method.

Example

This example uses the CreateTableDef and FillCache methods and the CacheSize, CacheStart and SourceTableName properties to enumerate the records in a linked table twice. Then it enumerates the records twice with a 50-record cache. The example then displays the performance statistics for the uncached and cached runs through the linked table.

Sub ClientServerX3()

    Dim dbsCurrent As Database
    Dim tdfRoyalties As TableDef
    Dim rstRemote As Recordset
    Dim sngStart As Single
    Dim sngEnd As Single
    Dim sngNoCache As Single
    Dim sngCache As Single
    Dim intLoop As Integer
    Dim strTemp As String
    Dim intRecords As Integer

    ' Open a database to which a linked table can be
    ' appended.
    Set dbsCurrent = OpenDatabase("DB1.mdb")
    ' Create a linked table that connects to a Microsoft SQL
    ' Server database.
    Set tdfRoyalties = _
        dbsCurrent.CreateTableDef("Royalties")
    tdfRoyalties.Connect = _
        "ODBC;DATABASE=pubs;UID=sa;PWD=;DSN=Publishers"
    tdfRoyalties.SourceTableName = "roysched"
    dbsCurrent.TableDefs.Append tdfRoyalties
    Set rstRemote = dbsCurrent.OpenRecordset("Royalties")

    With rstRemote
        ' Enumerate the Recordset object twice and record
        ' the elapsed time.
        sngStart = Timer

        For intLoop = 1 To 2
            .MoveFirst
            Do While Not .EOF
                ' Execute a simple operation for the
                ' performance test.
                strTemp = !title_id
                .MoveNext
            Loop
        Next intLoop

        sngEnd = Timer
        sngNoCache = sngEnd - sngStart

        ' Cache the first 50 records.
        .MoveFirst
        .CacheSize = 50
        .FillCache
        sngStart = Timer

        ' Enumerate the Recordset object twice and record
        ' the elapsed time.
        For intLoop = 1 To 2
            intRecords = 0
            .MoveFirst
            Do While Not .EOF
                ' Execute a simple operation for the
                ' performance test.
                strTemp = !title_id
                ' Count the records. If the end of the
                ' cache is reached, reset the cache to the
                ' next 50 records.
                intRecords = intRecords + 1
                .MoveNext
                If intRecords Mod 50 = 0 Then
                    .CacheStart = .Bookmark
                    .FillCache
                End If
            Loop
        Next intLoop
        sngEnd = Timer
        sngCache = sngEnd - sngStart

        ' Display performance results.
        MsgBox "Caching Performance Results:" & vbCr & _
            "    No cache: " & Format(sngNoCache, _
            "##0.000") & " seconds" & vbCr & _
            "    50-record cache: " & Format(sngCache, _
            "##0.000") & " seconds"
        .Close
    End With

    ' Delete linked table because this is a demonstration.
    dbsCurrent.TableDefs.Delete tdfRoyalties.Name
    dbsCurrent.Close

End Sub