Solved Replace Dlookup with as Sql Query (1 Viewer)

ahmedjamalaboelez

Ahmed J. Aboelez
Local time
Today, 05:55
Joined
Feb 25, 2015
Messages
79
Good day gentlemen,
I have Dlookup code as follow , and its work fine
Code:
[username_txtbox]=DLookup("user_fullname", "users_data", "[user_id]= [user_txtbox]")
but, is that possible to replace it with Sql query in vba and assign result to [username_txtbox]
Thanks ☺️,,
 

theDBguy

I’m here to help
Staff member
Local time
Today, 05:55
Joined
Oct 29, 2018
Messages
21,493
Hmm, why do you ask? A Domain Aggregate function like DLookup() generates its own recordset object (in the background). So, to replace it with something else in your VBA code, you can use a Recordset object. However, you will be in charge of managing or maintaining and closing that recordset. Whereas, DLookup() does all of that automatically for you.
 

ahmedjamalaboelez

Ahmed J. Aboelez
Local time
Today, 05:55
Joined
Feb 25, 2015
Messages
79
Hmm, why do you ask? A Domain Aggregate function like DLookup() generates its own recordset object (in the background). So, to replace it with something else in your VBA code, you can use a Recordset object. However, you will be in charge of managing or maintaining and closing that recordset. Whereas, DLookup() does all of that automatically for you.
the problem is iam using remote sqlserver database as backend , and Dlookup work fine with access database as backend , but with remote Sqlserver it takes some time specially when it concern many records with slow connection as attached image ,,
Untitled.png
 

theDBguy

I’m here to help
Staff member
Local time
Today, 05:55
Joined
Oct 29, 2018
Messages
21,493
Hi. Thanks for the additional information. If you're saying you have DLookup() inside a query, then that was bad. As mentioned, each call to DLookup() creates a recordset object. So, when the query runs, it will create as many recordsets as there are rows in the result. However, if you're using a query, I don't see how you can use VBA to replace your DLookup() column. Instead, a better approach is to JOIN the lookup table in your query, so the lookup information is immediately available to each row.
 

Pat Hartman

Super Moderator
Staff member
Local time
Today, 08:55
Joined
Feb 19, 2002
Messages
43,346
The best advice is - NEVER use domain functions in queries or VBA code loops. Period. In most cases, dLookup()s can be replaced by simple left joins and aggregate functions can be replaced by creating totals queries and joining to them.

So, replace the dLookups() by joining to the lookup table. Usually you will want to use a left join. Using an inner join might result in loosing records if entries don't exist in both tables.
 

June7

AWF VIP
Local time
Today, 04:55
Joined
Mar 9, 2014
Messages
5,488
Alternatives to DLookup:

1. query as you request might work faster

2. use a multi-column combobox instead of textbox and reference combobox column to pull username

3. include lookup table in form RecordSource
 

ahmedjamalaboelez

Ahmed J. Aboelez
Local time
Today, 05:55
Joined
Feb 25, 2015
Messages
79
The best advice is - NEVER use domain functions in queries or VBA code loops. Period. In most cases, dLookup()s can be replaced by simple left joins and aggregate functions can be replaced by creating totals queries and joining to them.

So, replace the dLookups() by joining to the lookup table. Usually you will want to use a left join. Using an inner join might result in loosing records if entries don't exist in both tables.
i agree with you in one case if i already modify or entering data directly to the database table , but actually iam using pending table to bring data from sqldatabase table to access table , after modifying or entering data local table directly update or insert data to the sqldatabase table , and iam using this to avoid direct impact on the main table and allow many users to work without errors , and avoid delays with much amount of data

Untitled.png
 

Pat Hartman

Super Moderator
Staff member
Local time
Today, 08:55
Joined
Feb 19, 2002
Messages
43,346
i agree with you in one case if i already modify or entering data directly to the database table ,
Not sure how you think this helps but whatever. If you can use a domain function, you can use a left join.
 

June7

AWF VIP
Local time
Today, 04:55
Joined
Mar 9, 2014
Messages
5,488
I have seen situations where a join was not possible and used DLookup(), usually because data structure is not normalized.
 

arnelgp

..forever waiting... waiting for jellybean!
Local time
Today, 20:55
Joined
May 7, 2009
Messages
19,247
here is a Replacement, it was said that recordset is much faster than the equivalent Domain function:
Code:
' 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


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

' ArnelGP 11 Feb 2014
' uses Top Value
    pstrTable = "(Select Top 1 " & pstrField & " As Expr9999 From " & pstrTable & _
            " Where " & IIf(pstrCriteria = "", "(1=1)", pstrCriteria) & _
            " Order By 1 Desc)"
    tMax = tLookup("Expr9999", pstrTable, , pdb, pLookupReset)
    'tMax = tLookup("max(" & pstrField & ")", pstrTable, pstrCriteria, pdb, pLookupReset)
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
    
' ArnelGP 11 Feb 2014
' uses Top Value
    
    pstrTable = "(Select Top 1 " & pstrField & " As Expr9999 From " & pstrTable & _
            " Where " & IIf(pstrCriteria = "", "(1=1)", pstrCriteria) & _
            " Order By 1 Asc)"
    tMin = tLookup("Expr9999", pstrTable, , pdb, pLookupReset)
    '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 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)

    ' chekc 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
        'MsgBox err.description, 16, "Error " & err.Number & " in tLookup() on table " & pstrTable & vbCr & vbCr & "SQL=" & strSQL
    End Select
    Resume tLookup_Exit
    Resume

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.Number & " In tLookupParam()"
    End Select
    Resume tCountParam_Exit
    Resume
End Function
 

MajP

You've got your good things, and you've got mine.
Local time
Today, 08:55
Joined
May 21, 2018
Messages
8,554
Here is another one. Not sure how it compares with the one from @arnelgp. His looks like it has more features.
But bottom line follow @Pat Hartman advice if possible.
 

Pat Hartman

Super Moderator
Staff member
Local time
Today, 08:55
Joined
Feb 19, 2002
Messages
43,346
If each row in the main query has the necessary fields to return a single correct row from the dLookup(), it also has the ability to join to the second table/query using a left join. You might not want to use a join because that may make your recordset not updateable but that would be the reason not that the tables are unnormalized. If you needed an updateable query and couldn't get it with the join and for some reason couldn't do the domain function on the form, then I would use the replacement that MagP linked to but only then. Using that function every time you need a dLookup() is probably a good idea. I don't so I forget about it

Don't loose sight of the fact that each domain function runs a separate query and with a large recordset, that is extremely expensive. If you have a 100 records in your test data, it makes absolutely no difference whether you use good techniques or poor techniques. I learned this very early on. Being new to Access, I looked at examples as we all do and the examples used dLookup() so that is what I did. the query was a conversion. It was taking data from an old application and converting three codes to values suitable to the new application and loading the new table. Worked fine when I was testing. Then I ran it on real data. The query took over three hours to run for 90,000 records. So I said, self, that isn't going to be good so I rethought the process, Luckily I had lots of experience with DB2 and multi-million row recordsets and knew that this was not a reasonable execution time for only 90,000 records so I changed the query to do THREE left joins (which is how I would have written the query for DB2 and COBOL) and the query ran in under TWO minutes. So, when you are working with real data, is two minutes better than three hours?

Like many things with Access, domain functions are a crutch. They are a huge convenience when you only need to get one value and I use them frequently but there are other, more efficient methods when working with queries and VBA code loops.
 

Users who are viewing this thread

Top Bottom