ACC2000: DAO Property Retrieval Slow with Linked Table Objects (200575)
The information in this article applies to:
This article was previously published under Q200575 Advanced: Requires expert coding, interoperability, and multiuser skills.
This article applies only to a Microsoft Access database (.mdb).
SYMPTOMS
When you use Data Access Objects (DAO) to retrieve properties for linked
TableDef objects, the process is much slower than when you use DAO to retrieve the properties for local TableDef objects.
CAUSE
The Microsoft Jet database engine must create a temporary query for each
property retrieval of a linked TableDef object. The Jet database engine does not need to do this when retrieving properties for local TableDef objects.
RESOLUTIONMicrosoft 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.
Instead of retrieving the properties for the linked TableDef objects in the current database, you can use DAO to open the database that the
TableDef objects actually reside in, and then retrieve the properties. To accomplish this, follow steps 1 through 17 in the "Steps to Reproduce Behavior" section later in this article, and substitute the following procedure for the procedure documented in step 15:
Sub EnumProperties(tDefName As String)
Dim db As Database
Dim tDef As TableDef
Dim tDefSourceTableName As String
Dim tDefProperty As Property
Dim PropCount As Integer
Dim dbPath As String
Dim tDefField As Field
Dim StartTime As Date, EndTime As Date
StartTime = Now
Set db = CurrentDb
Set tDef = db.TableDefs(tDefName)
If (tDef.Attributes And dbAttachedTable) <> 0 Then
If InStr(tDef.Connect, ".mdb") > 0 Then
tDefSourceTableName = tDef.SourceTableName
dbPath = Right$(tDef.Connect, _
Len(tDef.Connect) - _
InStr(tDef.Connect, "="))
Set db = DBEngine(0).OpenDatabase(dbPath)
Set tDef = db.TableDefs(tDefSourceTableName)
End If
End If
For Each tDefProperty In tDef.Properties
Next
For Each tDefField In tDef.Fields
For Each tDefProperty In tDefField.Properties
PropCount = PropCount + 1
Next
Next
EndTime = Now
Debug.Print
Debug.Print "Table: " & tDef.Name
Debug.Print "Number of Table and Field Properties: " & _
tDef.Properties.Count + PropCount
Debug.Print "Total Time: " & _
DateDiff("s", StartTime, EndTime) & " second(s)"
db.Close
End Sub
STATUSMicrosoft has confirmed that this is a problem in the Microsoft products that are listed at the beginning of this article.
Modification Type: | Major | Last Reviewed: | 6/23/2005 |
---|
Keywords: | kbprb kbProgramming KB200575 |
---|
|