Ms-Access Advanced VBA Programming Techniques, Tips and Tricks.

Dynamic Dlookup in Query Column

If we need only a single column value from a related table to incorporate into a Microsoft Access Query then we can use a DLookup() function to bring that value into the Query Column. Normally we place that Table also into the Query's design surface, establish link between Primary Key of the main table and Foreign Key of the other table and place the required field into the query column. Here, we will examine an interesting solution to a small problem with a dlookup() function in a query column. The above method that normally we follow have some issues when implemented in the following situations, which we are going to explore.

The DLookup(“TaxRate2005”,”tblTaxRates”,”[Product Code] = ‘” & [ProductCode] & “’”) Function is used in a Query Column to pick up Sale Tax Rate from the tblTaxRates Table, for each item sold, for calculating the Sale Tax Value for the actual Sale value.  The Tax Rate will change every year during annual budgeting of the government.  The Company maintains the history of these changes and adds a new tax-rate-field with Year as Suffix to the tblTaxRates Table like: TaxRate2005, TaxRate2006, TaxRate2007 etc.  Take a look at the sample image given below:

The Query Column name is TaxRate where the Dlookup() Function is inserted, irrespective of TaxRate2005 or TaxRate2006 or TaxRate2007 is selected in the function parameter like: TaxRate:Dlookup(“TaxRate2005”,”tblName”,”Criteria”).  When we design a report we can use the report control name as TaxRate and no need to modify every time.

Check the sample Query result image given below:

Now, assume that there are Orders placed during December with the applicable Tax Rate at that time. There are Orders placed for materials immediately after the budget implementation with revised sale tax rate.  We have to prepare some invoices with previous year sale tax rates and others with current year rates.  That means the Dlookup() function will look like Dlookup(“TaxRate2005”,” “,” “) for previous year and Dlookup(“TaxRate2006”,” “, “ “) for current year.  The table name and criteria part is omitted for clarity. As you can see the first parameter of the function must be changed every time for printing previous year and current year invoices.

We cannot ask the User to go in and change the Query design.  There must be a way to define that particular parameter of the function dynamically to refer to different tax rate columns on the tblTaxRates.  The solution is very simple, design a small Form with a Text Box and a Command button and let the user type the tax rate field name  in the Text Box (or create a Combo Box if required) and click the Command Button to refresh the Query and open the Report that uses this Query as record source.  Sample image of the Query parameter Form is given below:

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

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

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

The sample SQL of the Query is given below:

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

Trending

Search

Infolinks Text Ads

Popular Posts

Search This Blog

Blog Archive

Powered by Blogger.

Labels

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

Featured Post

Activity Dates and Quarterly Reports

There are four Quarters in a Year: Jan - Mar = 1st Quarter Apr - Jun = 2nd Jul - Sep = 3rd Oct - Dec = 4th First three months of the yea...

Labels

Blog Archive

Recent Posts