Learn Microsoft Access Advanced Programming Techniques, Tips and Tricks.

Dynamic Dlookup in Query Column

Introduction.

If we need only a single value in a query column from a related table, we often use the DLookup() function.

Normally, the standard approach is to add the related table to the query design surface.  Establish a relationship between the Primary Key of the main table and the Foreign Key of the other table, and then pull the required field value into the query column.

However, in certain cases, this method can lead to complications. To illustrate, let’s look at an interesting scenario where DLookup() is used inside a query column.

Suppose we use the following expression to pick up the Sales Tax Rate for each sold item from the tblTaxRates table, so that the tax value can be calculated on the sales amount:

DLookup("TaxRate2005", "tblTaxRates", "[Product Code] = '" & [ProductCode] & "'")

Here’s the catch: the tax rate changes every year as part of the government’s annual budget revisions. The company maintains a history of these changes by adding a new tax rate field for each year, with the year as a suffix—e.g., TaxRate2005, TaxRate2006, TaxRate2007, and so on.

A sample image of the tblTaxRates table is shown below:

In the query, we assign a consistent column name, TaxRate, and insert the DLookup() function as its expression. For example:

TaxRate: DLookup("TaxRate2005","tblTaxRates","[Product Code]='" & [ProductCode] & "'")

Here, the function may refer to TaxRate2005, TaxRate2006, or TaxRate2007, depending on the year being processed. But the query output column name remains the same, TaxRate.

This consistency is useful when designing reports. On the report, we can place a control bound to the TaxRate field. Since the query always produces a column named TaxRate, the report design does not need to be modified each time the tax year changes.

Check the sample Query result image given below:


Applying Different Tax Rates

Now, consider a practical scenario:

  • Some orders were placed in December, when the previous year’s tax rate still applied.

  • Other orders were placed after the budget, when the new tax rate came into effect.

When preparing invoices, this means:

  • Older invoices must use the TaxRate2005 field.

  • Newer invoices must use the TaxRate2006 field.

In other words, the first parameter of the DLookup() function needs to change each time:

DLookup("TaxRate2005","","") DLookup("TaxRate2006","","")

(The table name and criteria are omitted for simplicity.)

Obviously, we cannot expect the user to open the query design and manually update the field name every time they need to print invoices from a different year.

The solution is straightforward:

  1. Create a small Form with a Text Box (or, better yet, a Combo Box that lists available tax rate fields).

  2. Provide a Command Button on the form.

  3. The user enters (or selects) the required tax rate field name and clicks the button.

  4. The code behind the button dynamically updates the query, refreshes it, and then opens the Report that depends on it.

This approach lets the user control which TaxRate field the DLookup() uses, without ever touching the query design.

The Textbox name is Tax on the above form.  Our Dlookup() function in the Order Details Query column will look as given below:

TaxRate:DLookup([Forms]![InvoiceParam]![Tax], _
”tblTaxRates”,”[ProdCode]= '” & [Product Code] & “'”)

In the criteria part, the ProdCode field of the tblTaxRate table should match with the (Product Code) field of the Products Table linked to the Order Details Table to return the tax rate value for each item on the Order Details table.

The sample SQL of the Query.

SELECT [Order Details].[Order ID],
 Products.[Product Code],
 Products.[Product Name],
 [Order Details].Quantity,
 [Order Details].[Unit Price],
 [Quantity]*[Unit Price] AS SaleValue,
 Val(DLookUp([Forms]![InvoiceParam]![Tax],"TaxRates", _
 "[ProdCode]='" & [Product Code] & "'")) AS TaxRate,
 [SaleValue]*[TaxRate] AS SaleTax,
 [SaleValue]+[SaleTax] AS TotalSaleValue
FROM Products INNER JOIN [Order Details] _
ON Products.ID = [Order Details].[Product ID];

The Command Button Click Event Procedure can run the following code to open the Sales Invoice Report after refreshing the change on the Form:

Private Sub cmdRun_Click()
Me.Refresh
DoCmd.OpenReport "SalesInvoice", acViewPreview
End Sub
Technorati Tags:
Share:

No comments:

Post a Comment

Comments subject to moderation before publishing.

PRESENTATION: ACCESS USER GROUPS (EUROPE)

Translate

PageRank

Post Feed


Search

Popular Posts

Blog Archive

Powered by Blogger.

Labels

Forms Functions How Tos MS-Access Security Reports msaccess forms Animations msaccess animation Utilities msaccess controls Access and Internet MS-Access Scurity MS-Access and Internet Class Module External Links Queries Array msaccess reports Accesstips WithEvents msaccess tips Downloads Objects Menus and Toolbars Collection Object MsaccessLinks Process Controls Art Work Property msaccess How Tos Combo Boxes Dictionary Object ListView Control Query VBA msaccessQuery Calculation Event Graph Charts ImageList Control List Boxes TreeView Control Command Buttons Controls Data Emails and Alerts Form Custom Functions Custom Wizards DOS Commands Data Type Key Object Reference ms-access functions msaccess functions msaccess graphs msaccess reporttricks Command Button Report msaccess menus msaccessprocess security advanced Access Security Add Auto-Number Field Type Form Instances ImageList Item Macros Menus Nodes RaiseEvent Recordset Top Values Variables Wrapper Classes msaccess email progressmeter Access2007 Copy Excel Export Expression Fields Join Methods Microsoft Numbering System Records Security Split SubForm Table Tables Time Difference Utility WScript Workgroup database function msaccess wizards tutorial Access Emails and Alerts Access Fields Access How Tos Access Mail Merge Access2003 Accounting Year Action Animation Attachment Binary Numbers Bookmarks Budgeting ChDir Color Palette Common Controls Conditional Formatting Data Filtering Database Records Defining Pages Desktop Shortcuts Diagram Disk Dynamic Lookup Error Handler External Filter Formatting Groups Hexadecimal Numbers Import Labels List Logo Macro Mail Merge Main Form Memo Message Box Monitoring Octal Numbers Operating System Paste Primary-Key Product Rank Reading Remove Rich Text Sequence SetFocus Summary Tab-Page Union Query User Users Water-Mark Word automatically commands hyperlinks iSeries Date iif ms-access msaccess msaccess alerts pdf files reference restore switch text toolbar updating upload vba code