Speed Issue (1 Viewer)

hey23

New member
Local time
Yesterday, 20:15
Joined
Jun 24, 2009
Messages
3
Hi,

I used a Access database which was used by 20 people in a building(but max 4 people were using it concurrently). Since the database got bigger and bigger, I changed the backend to MySQL. Also within the form, I used VBA code to let MySQL server to execute the query. The thing frustrated me is: The speed is even lower than before! I don't know what reason it could be. Can someone experienced tell me how to find the reason and to solve it?

Some infomation about the queries I am using: INSERT and UPDATE are seldomly used, SELECT is used a lot, GROUP BY and various functions are also used a lot. Some tables are as big as 800,000 records.

Thanks! Pls let me know what else information should be provided.
 

Atomic Shrimp

Humanoid lifeform
Local time
Today, 04:15
Joined
Jun 16, 2000
Messages
1,954
Are you running any queries that might be missing a join? For example:

SELECT tblinvoices.InvoiceID, tblinvoices.InvoiceNum, tblinvoices.CustomerID, tblcustomers.Customername, tblcustomers.CustomerPhone
FROM tblinvoices INNER JOIN tblcustomers ON tblinvoices.CustomerID = tblcustomers.CustomerID;

will yield the same results as:

SELECT tblinvoices.InvoiceID, tblinvoices.InvoiceNum, tblinvoices.CustomerID, tblcustomers.Customername, tblcustomers.CustomerPhone
FROM tblinvoices, tblcustomers
WHERE (((tblinvoices.CustomerID)=[tblcustomers].[customerID]));

But in the latter case, because there is no join Access might* first retrieve every possible combination of invoice and customer (the cartesian result), then discard all rows where the customerID does not match.

*I'm not sure of this - it might apply to all, some or no query execution plans.
 

hey23

New member
Local time
Yesterday, 20:15
Joined
Jun 24, 2009
Messages
3
Are you running any queries that might be missing a join? For example:

SELECT tblinvoices.InvoiceID, tblinvoices.InvoiceNum, tblinvoices.CustomerID, tblcustomers.Customername, tblcustomers.CustomerPhone
FROM tblinvoices INNER JOIN tblcustomers ON tblinvoices.CustomerID = tblcustomers.CustomerID;

will yield the same results as:

SELECT tblinvoices.InvoiceID, tblinvoices.InvoiceNum, tblinvoices.CustomerID, tblcustomers.Customername, tblcustomers.CustomerPhone
FROM tblinvoices, tblcustomers
WHERE (((tblinvoices.CustomerID)=[tblcustomers].[customerID]));

But in the latter case, because there is no join Access might* first retrieve every possible combination of invoice and customer (the cartesian result), then discard all rows where the customerID does not match.

*I'm not sure of this - it might apply to all, some or no query execution plans.

It might be not the case. Actually I used JOIN a lot:confused:
 

Guus2005

AWF VIP
Local time
Today, 05:15
Joined
Jun 26, 2007
Messages
2,642
Stay off the various functions. They tend to slow the query execution. Especially IIF. That's a nasty one. Don't use DLOOKUP in your queries either. search for a function called TLOOKUP instead. It's a lot faster with attached tables.

HTH:D
 

marianne

Registered User.
Local time
Yesterday, 20:15
Joined
Mar 26, 2009
Messages
327
haven't used TLookUp. Is there such one? What's the difference between the two? What version of Access does it have?
 

hey23

New member
Local time
Yesterday, 20:15
Joined
Jun 24, 2009
Messages
3
Stay off the various functions. They tend to slow the query execution. Especially IIF. That's a nasty one. Don't use DLOOKUP in your queries either. search for a function called TLOOKUP instead. It's a lot faster with attached tables.

HTH:D

Don't know there is a TLOOKUP either. I do use IF a lot, but how to stay off it?
 

Guus2005

AWF VIP
Local time
Today, 05:15
Joined
Jun 26, 2007
Messages
2,642
Here is TLOOKUP
Code:
Option Compare Database   'Use database order for string comparisons
Option Explicit

' Fast Replacement Functions for DLookup, DCount & DSum , DMax & DMin
'
' Notes:
' Any spaces in field names or table names will probably result in an error
' If this is the case then provide the brackets yourselfs, e.g.
' tLookup("My field","My table name with spaces in") will blow big time
' tLookup("[My field]","[My table name with spaces in]") will be ok
' These functions will not bracket the field/table names for you so as to
' remain as flexible as possible, e.g. you can call tSum() to add or multiply or
' whatever along the way, e.g. tSum("Price * Qty","Table","criteria") or if you're
' feeling adventurous, specify joins and the like in the table name.
'
' See tLookup function for changes from last version
'
' Uses DAO
'
' VB Users
' Get rid of tLookupParam() and the case in the error trapping
' of tLookup() that calls it, this uses a function built-in to
' MS-Access.

Public Enum tLookupReset
    tLookupDoNothing = 0
    tLookupRefreshDb = 1
    tLookupSetToNothing = 2
End Enum

Public Declare Function GetTickCount Lib "kernel32" () As Long

Function TLookup(pstrField As String, pstrTable As String, Optional pstrCriteria As String, Optional pdb As Database, Optional pLookupReset As tLookupReset = tLookupDoNothing) As Variant
    On Error GoTo tLookup_Err
    
    ' Function  tLookup
    ' Purpose:  Replace DLookup, which is slow on attached tables
    '           For where you can't use TbtLookup() if there's more
    '           than one field in the criteria or field is not indexed.
    ' Created:  9 Jan 1996 T.Best
    ' Mod       1 Feb 1996 T.Best
    '   Error Trapping brought in line with this procurement system.
    
    ' Mod       13 Apr 1999 T.Best
    '   Lookups to ODBC datasource use the gdbSQL database object.
    
    ' Mod       14 Apr 1999 T.Best
    '   gdbSQL object no good if doing lookup on a local table, DOH!
    
    ' Mod       11 Jan 2002 G.Hughes
    '   Removed gdbSQL as it was slowing tLookup Down.!!!!!!!!!
    
    ' Mod       Unlogged
    '   Someone put gdbSQL back in
    
    ' Mod       27 Jan 2003 T. Best
    '   Optimise gdbSQL to use Pass-through, it wickedly fast
    
    ' mod       13 Mar 2003
    '   Taken out gdbSQL for redistribution and replaced
    '   the DbEngine with CurrentDB to avoid the now well
    '   documented (in CDMA) DbEngine reference bug.
    '   Added tLookupReset Parameter which does the following
    '   tLookupDoNothing    Do nothing
    '   tLookupRefreshDb    Refreshes collections on the db
    '   tLookupCloseDb      Sets the db to nothing
    '   Also added a db parameter so programmer can call it using
    '   their own db variable, which may be something they opened
    '   elsewhere (Idea by D.Fenton in CDMA).
    
    Static dbLookup As DAO.Database
    Dim rstLookup As DAO.Recordset
    Dim varvalue As Variant
    Dim strSql As String
    
    ' if calling function sends a db then we'll use that
    If Not pdb Is Nothing Then
        Set dbLookup = pdb
    Else
        ' If our db vari is not initialised or the calling
        ' process wants the db objects refreshed then we'll
        ' set the db var using CurrentDb()
        If dbLookup Is Nothing Or pLookupReset = tLookupRefreshDb Then
            If Not dbLookup Is Nothing Then
                Set dbLookup = Nothing
            End If
            Set dbLookup = CurrentDb()
        End If
    End If
    
    
    ' If no criteria specified then we don't even want to get as far
    ' as putting the word "where" in there
    If Len(pstrCriteria) = 0 Then
        strSql = "Select " & pstrField & " From " & pstrTable
    Else
        ' handle those instances where you call tLookup using a field
        ' on a form but can't be bothered to check whether it's null
        ' first before calling, e.g. =tLookup("col1","table","col2=" & txtWhatever)
        ' if txtWhatever was null it would cause an error, this way if there's
        ' nothing after the "=" sign then we assume it was null so we'll make
        ' it look for one.
        ' You may want to handle this differently and avoid looking up
        ' data where the criteria field is null and just always return a
        ' null in which case you'd need to add code to avoid doing the
        ' lookup altogether or just change the criteria to " = Null" as
        ' nothing will ever match with " = Null" so the function would
        ' return null.
        If right$(RTrim$(pstrCriteria), 1) = "=" Then
            pstrCriteria = RTrim$(pstrCriteria)
            pstrCriteria = Left$(pstrCriteria, Len(pstrCriteria) - 1) & " is Null"
        End If
        
        ' build our SQL string
        strSql = "Select " & pstrField & " From " & pstrTable & " Where " & pstrCriteria
    End If
    
    ' now open a recordset based on our SQL
    Set rstLookup = dbLookup.OpenRecordset(strSql, dbOpenSnapshot, dbReadOnly)
    
    ' check if we returned anything at all
    If Not rstLookup.BOF Then
        ' return the value returned in the query
        varvalue = rstLookup(0)
    Else
        ' no records matched, return a null
        varvalue = Null
    End If
    TLookup = varvalue

tLookup_Exit:
    On Error Resume Next
    rstLookup.Close
    Set rstLookup = Nothing
    Exit Function

tLookup_Err:
    Select Case Err
        Case 3061
            ' Error 3061 - Too Few Parameters - Expected x, you know those programmers
            ' should really parse out those form object references for themselves but
            ' we can try to retrieve the situation here by evaluating any parameters
            ' we find in the SQL string.
            TLookup = TLookupParam(strSql, dbLookup)
        Case Else
            ErrorProc Err, Error$, "Tlookup", "modLookup"
'            MsgBox Err.Description, 16, "Error " & Err & " in tLookup() on table " & pstrTable & vbCr & vbCr & "SQL=" & strSQL
    End Select
    Resume tLookup_Exit
    Resume

End Function

Function TCount(pstrField As String, pstrTable As String, Optional pstrCriteria As String, Optional pdb As Database, Optional pLookupReset As tLookupReset = tLookupDoNothing) As Long
    
    ' Function tCount
    ' Purpose: Replace DCount, which is slow on attached tables
    ' Created: 1 Feb 1996 T.Best

    ' TB 28 Jan 2003
    ' Make this call TLookup() so we'll only need concentrate on
    ' one set of error handling code
    TCount = TLookup("count(" & pstrField & ")", pstrTable, pstrCriteria, pdb, pLookupReset)
    
End Function
Function TMax(pstrField As String, pstrTable As String, Optional pstrCriteria As String, Optional pdb As Database, Optional pLookupReset As tLookupReset = tLookupDoNothing) As Variant
    
    ' Function tMax
    ' Purpose: Replace DMax, which is slow on attached tables
    ' Created: 1 Feb 1996 T.Best

    ' TB 28 Jan 2003
    ' Make this call TLookup() so we'll only need concentrate on
    ' one set of error handling code
    TMax = TLookup("max(" & pstrField & ")", pstrTable, pstrCriteria, pdb, pLookupReset)
    Exit Function
End Function

Function TMin(pstrField As String, pstrTable As String, Optional pstrCriteria As String, Optional pdb As Database, Optional pLookupReset As tLookupReset = tLookupDoNothing) As Variant
    
    ' Function tMin
    ' Purpose: Replace DMin, which is slow on attached tables
    ' Created: 1 Feb 1996 T.Best
    
    ' TB 28 Jan 2003
    ' Make this call TLookup() so we'll only need concentrate on
    ' one set of error handling code
    TMin = TLookup("min(" & pstrField & ")", pstrTable, pstrCriteria, pdb, pLookupReset)
    
End Function

Function TSum(pstrField As String, pstrTable As String, Optional pstrCriteria As String, Optional pdb As Database, Optional pLookupReset As tLookupReset = tLookupDoNothing) As Double
    
    ' Function tSum
    ' Purpose: Replace DSum, which is slow on attached tables
    ' Created: 1 Feb 1996 T.Best

    ' TB 28 Jan 2003
    ' Make this call TLookup() so we'll only need concentrate on
    ' one set of error handling code
    TSum = Nz(TLookup("sum(" & pstrField & ")", pstrTable, pstrCriteria, pdb, pLookupReset), 0)

End Function

Function TLookupParam(pstrSQL As String, pdb As Database) As Variant
    ' Called when tLookup, tCount, tMax, tMin or tSum have bombed out
    ' with an expected parameter error, will go and create a querydef
    ' and then attempt to evaluate the parameters
    ' Error Trapped: 12/02/1999 10:21:24 Admin
    On Error GoTo tCountParam_Err
    Dim qdf As DAO.QueryDef
    Dim rst As DAO.Recordset
    Dim prm As DAO.Parameter
    Dim strMsg As String
    Dim i As Long
    
    Set qdf = pdb.CreateQueryDef("", pstrSQL)
    strMsg = vbCr & vbCr & "SQL=" & pstrSQL & vbCr & vbCr
    For i = 0 To qdf.Parameters.Count - 1 ' Each prm In qdf.Parameters
        Set prm = qdf.Parameters(i)
        strMsg = strMsg & "Param=" & prm.Name & vbCr
'        Debug.Print prm.Name
        prm.Value = Eval(prm.Name)
        Set prm = Nothing
    Next
    Set rst = qdf.OpenRecordset()
    rst.MoveFirst
    TLookupParam = rst(0)
    
tCountParam_Exit:
    On Error Resume Next
    Set prm = Nothing
    rst.Close
    Set rst = Nothing
    qdf.Close
    Set qdf = Nothing
    Exit Function
    
tCountParam_Err:
    Select Case Err
        Case Else
            MsgBox Err.Description & strMsg, 16, "Error #" & Err & " In tLookupParam()"
    End Select
    Resume tCountParam_Exit
    Resume
End Function
Amazing that these functions are faster than the build-in ones.

You can avoid using IIF's by adding a table and joining to it. Especially if you use nested IIF statements.
Single IIF's are more difficult to replace then nested ones.

Some other speed issues in VBA: Prefer Left$, Mid$, etc instead of Left, Mid, etc The first return strings, the latter return variant.
In an IF statement checking for a zero length string is faster than checking if it is empty:
Code:
'Don't use
If strSql = "" then
   'code
endif
'Use
If Len(strSql) = 0 then
 'code
endif
Enjoy!


Could you post a sample?
 

allan57

Allan
Local time
Today, 04:15
Joined
Nov 29, 2004
Messages
336
Another thing to check for is the criteria fields you are using have indexes
 

Users who are viewing this thread

Top Bottom