ACC2: DLookup() Usage, Examples, and Troubleshooting TipsID: Q136460
|
Novice: Requires knowledge of the user interface on single-user computers.
This article describes how to use the DLookup() function, and includes
examples and tips. The following topics are addressed in this article:
- A function with no criteria
- Specifying numeric criteria
- Specifying numeric criteria that comes from a field on a form
- Specifying textual criteria
- Specifying textual criteria that comes from a field on a form
- Specifying date criteria
- Specifying multiple fields in the criteria
- Tips for troubleshooting and debugging DLookup() expressions
When you use the DLookup() function, difficulties may result if you do not
set up and supply the criteria expression correctly. The criteria
expression is common to many other aggregate (totals) functions, such as
DSum(), DFirst(), DLast(), DMin(), DMax(), and DCount(). Therefore, the
following material may help you understand those domain aggregate
functions as well as the DLookup() function.
DLookup(Expression, Domain [, Criteria] )
The function has three arguments: the expression, the domain, and the
criteria. (Note that the criteria argument is optional.)
=DLookUp("[Last Name]", "Employees")
=DLookUp("[Last Name]", "Employees", "[Employee ID] = 7")
=DLookUp("[Last Name]", "Employees", _
"[Employee ID] = Form![Employee ID]")
=DLookUp("[Last Name]", "Employees", _
"[Employee ID] = " & [Employee ID])
=DLookUp("[Last Name]", "Employees", _
"[Employee ID] = " & Forms![Orders]![Employee ID])
The three examples above return the same results.
"[Employee ID] = [Employee ID]"
computes to
"1 = 1"
and would therefore be the first record that matched the criteria.
"[Employee ID] = " & [Employee ID]
computes to
"[Employee ID] = " & 7
which, when concatenated, computes to:
"[Employee ID] = 7"
If you do not specify the full form reference (which the second example
above does not), Microsoft Access assumes that you are referring to the
current form.
=DLookUp("[Last Name]", "Employees", _
"[Employee ID] = Forms![Orders]![Employee ID]")
In this example, the full form reference is enclosed inside the criteria's
quotation marks. In this case, Microsoft Access correctly looks up the
value when the form first opens, but only until the Employee ID field is
changed by modifications to a record or the addition of a record.
Microsoft Access does not automatically recompute the new employee last
name value after such a change. You can manually recompute the expression
by placing the insertion point on the control and then pressing F9.
=DLookUp("[Title]", "Employees", "[Last Name] = 'Callahan'")
Note that you can use double quotation marks instead of single quotation
marks, although single quotation marks are preferred. Use two double
quotation marks to replace one single quotation mark. The following
example uses double quotation marks and is equivalent to the example above:
=DLookUp("[Title]", "Employees", "[Last Name] = ""Callahan""")
=DLookup("[Contact Name]", "Customers", _
"[Customer ID]='" & [Customer ID]& "'")
-or-
=DLookup("[Contact Name]", "Customers", _
"[Customer ID]='" & Forms![Orders]![Customer ID]& "'")
In the second example, the criteria is made up by concatenating three
string expression pieces. The first is "[Customer ID]= '", the second is
the value contained in the actual Customer ID field, and the third is the
closing single quotation mark enclosed in double quotation marks.
"[Customer ID]= '" & [Customer ID]& "'"
computes to
"[Customer ID]= '" & "ALFKI" & "'"
which, when concatenated, computes to:
"[Customer ID]= 'ALFKI'"
=DLookUp("[Last Name]", "Employees", "[Birth Date] = #01-27-66#")
=DLookUp("[Order ID]", "Orders", _
"[Customer ID]= 'SIMOB' And [Employee ID] = 2")
This statement returns Order ID 10556, which is the first Order ID that
matches the criteria. Order ID 10669 also matches the criteria.
' Declare the variables
Dim CustID As String
Dim EmpID As Long
Dim Result
' Assign values to the variables to be used in the criteria
CustID = "SIMOB"
EmpID = 2
Result = DLookup("[Order ID]", "Orders", _
"[Customer ID]= '" & CustID & "' And [Employee ID] = " & EmpID)
MsgBox Result
If the DLookup() function is unsuccessful, the variable Result contains
Null.
"[Customer ID]= '" & CustID & "' And [Employee ID] = " & EmpID
computes to
"[Customer ID]= '" & "SIMOB" & "' And [Employee ID] = " & 2
which, when concatenated, computes to:
"[Customer ID]= 'SIMOB' And [Employee ID] = 2"
You can use the next example to find an employee whose birthday falls on
today's date:
=DLookUp("[Last Name]", "Employees", _
"Month([Birth Date]) = " & Month(Date) & " And Day([Birth Date]) _
= " & Day(Date))
If today's date is 12/2/93, the original criteria expression:
"Month([Birth Date]) = " & Month(Date) & " And Day([Birth Date]) = " _
& Day(Date)
computes to
"Month([Birth Date]) = " & 12 & " And Day([Birth Date]) = " & 2
which, when concatenated, computes to:
"Month([Birth Date]) = 12 And Day([Birth Date]) = 2"
=DLookUp("[Order ID]", "Orders", _
"[Customer ID]= '" & Forms![MyForm]![Customer ID] _
& "' And [Employee ID] = " & Forms![MyForm]![Employee ID])
Note that the criteria includes multiple fields in the lookup criteria, one
of which is numeric and one of which is textual.
? DLookUp("[Order ID]", "Orders")
Microsoft Access will perform the calculation and display the result on
the next line in the Immediate window.
? Forms![MyForm]![Customer ID]
-and-
? Forms![MyForm]![Employee ID]
? DLookUp("[Order ID]", "Orders", "[Customer ID]= 'SIMOB'")
-and-
? DLookUp("[Order ID]", "Orders", "[Employee ID] = 2")
? DLookUp("[Order ID]", "Orders", _
"[Customer ID]= '" & Forms![MyForm]![Customer ID]& "'")
-and-
? DLookUp("[Order ID]", "Orders", _
"[Employee ID] = " & Forms![MyForm]![Employee ID])
Microsoft Access "User's Guide," Chapter 18, "Using Expressions in Forms,"
page 459
Microsoft Access "Language Reference," pages 194-195
Microsoft Access "Building Applications," Chapter 9, "Debugging," pages 213-
216
For more information on how to use the DLookUp() function in
Microsoft Access versions 7.0 and 97, please see the following article
in the Microsoft Knowledge Base:
Q136122 ACC: DLookup() Usage, Examples, and Troubleshooting (95/97)
Additional query words:
Keywords : kbusage
Version : WINDOWS:2.0
Platform : WINDOWS
Issue type : kbinfo
Last Reviewed: July 13, 1999