Learn Microsoft Access Advanced Programming Techniques, Tips and Tricks.

Showing posts with label Queries. Show all posts
Showing posts with label Queries. Show all posts

Combining Active and Backup Database Records in Union Query

Introduction.

Microsoft Access database can be a maximum of 2GB in size. We can back up old Records (like previous year transactions) into a Backup database safely for later use if the need arises. After the safe backup of these transactions, they can be deleted from the active database and Run Compact & Repair Utility to optimize the database performance in day-to-day activities.

There are times that we need the old data for analysis purposes, like next year's budgeting, sales target setting, and so on. At this point we will need old records to combine with the existing data of the active master-table, in the current database, to do various analysis runs.

The Union Query Solution.

We can merge records of both the active table and backup table (with the same name) in a Union Query.

A simple example is given below:

SELECT Export.* 
FROM Export
UNION ALL SELECT Export.*
FROM Export IN 'G:\NEW FOLDER\DB1.MDB';

From the above example, you can see that the name of the table Export in an active database and backup database(DB1.MDB) are the same. No need to link the table to the active database to access the data from the backup database.

Share:

RUNSQL Action in MACRO and VBA

Introduction.

The  Microsoft Access beginners can get confused with the usage of RUNSQL Action in Macro and DoCmd.RUNSQL method of Visual Basic for Applications (VBA). Whether you run this Action in Macro or in VBA you must provide the SQL Statement of an Action-Query or Data-Definition Query Types only. If you are not sure which are these types of queries then refer to the following list:

Action Query Type.

Action Query Types
Query Type Statement
Append INSERT INTO
Delete DELETE
Make-Table SELECT ... INTO
Update UPDATE

Data Definition Queries.

Data-Definition Query Types
Query Type Statement
Create a table CREATE TABLE
Alter a table ALTER TABLE
Delete a table DROP TABLE
Create an Index CREATE INDEX
Delete an Index DROP INDEX

Using the SQL Statement of any other Query type in RUNSQL Action will end up in errors. In Macro the length of an SQL statement can be a maximum of 256 characters or less.

The DoCmd.RUNSQL method of VBA can execute an SQL statement with a maximum length of 32768 characters or less.

Note: You are not allowed to give an existing Query Name as a parameter to this command. But, in VBA you can load the SQL Statement of a predefined query into a String Variable and use it as the parameter to the DoCmd.RUNSQL command. 

Example-1:

Public Function DelRecs()
'Existing Delete Query’s SQL is used in this example
Dim db As Database, qryDef As QueryDef
Dim strSQL As String

'Read and save the SQL statement from 'Query48'
'and load into strSQL string variable
Set db = CurrentDb
Set qryDef = db.QueryDefs("Query48")
strSQL = qryDef.SQL

'Execute the SQL statement after
'disabling warning messages
DoCmd.SetWarnings False
DoCmd.RunSQL strSQL
DoCmd.SetWarnings True

'Using DoCmd.OpenQuery Command to run a Delete Query
DoCmd.SetWarnings False
DoCmd.OpenQuery "Query48", acViewNormal
DoCmd.SetWarnings True

End Function

The RUNSQL Action of Macro Modifies/Deletes information of several records in one go. Before executing the Action Query Microsoft Access gives out a warning message, appropriate to the action specified, and waits for the User's responses. The User must respond to proceed/cancel the action specified.

Once the procedure is perfected, by test running the Action Query several times, we can ask Microsoft Access to turn OFF the Warning Messages during the execution of RUNSQL Action. After the Query running step, give control back to MS-Access by turning ON the Warning Message detection. From that point onwards MS-Access will be watching for unexpected errors in the System and warns the User, as and when it happens.

The SetWarnings Action in Macro and DoCmd.SetWarnings Method in VBA is used for this purpose when data processing for a report involves one or more action query steps placed in a Macro. Check the image of a Macro, given below in the design view, with the SetWarnings settings, before and after the RUNSQL Action in the Macro. The first Action in the Macro is Setwarnings with the Parameter value NO to turn off the Warning Messages when the RUNSQL Action executes in the next step. The SetWarnings Action with the Parameter value YES turns ON the Warning Messages in step three, so that MS-Access can take care of future unexpected System Errors of any kind, as and when it happens.


Example-2:

Create a Table with the Data-definition SQL

Warning: Double-check that you are not using any existing table name for this sample run.

Public Function DataDefQuery()
Dim strSQL As String

strSQL = "CREATE TABLE Books  (Title TEXT(50) NOT NULL, Author TEXT(50) NOT NULL, PublishDate DATE, Price CURRENCY)"

DoCmd.RunSQL strSQL

End Function

The OpenQuery Action in Macro and DoCmd.OpenQuery Method of VBA uses the name of a predefined Query (of any type) to open them in any of the following Views:

  • Design View
  • Datasheet View
  • Print Preview
  • Pivot Table
  • Pivot Chart
Share:

Adding Data directly into External Databases

Introduction.

 The Back-End, Front-End database designs are common in MS-Access.  The back-end can be MS-Access, dBase, SQL Server, Excel, or Paradox databases with their linked Tables.  Once the tables are linked they function as if they are the native tables of the Access Database.  You can design Queries, Forms, Report on them and manage them from FE.

But, can we manage without directly linking them to the FE?  For example; can we create a Query in the current database using an external Table (not a linked table) from another MS-Access database?

This topic we have already discussed earlier proved that it is possible.  Check the following Blog Posts to learn this trick on different types of external data sources:

  1. Opening External Data Sources
  2. Opening dBase Files directly
  3. Opening Excel Database directly
  4. Display Excel Values directly on Form
  5. Database Connection String Property
  6. Source ConnectStr Property and ODBC
  7. Link External Tables with VBA
  8. Lost Links of External Tables
  9. MS-Access Live data in Excel
  10. MS-Access Live data in Excel-2

As you can see from the above list that serial numbers 1 to 6 methods are used for bringing external data into Access in different ways without keeping them linked to the Access Database.  When working with dBase or FoxPro Tables, the path to the Folder, where the dBase/FoxPro Table is located stands as the database name.

If you have gone through the second Article Opening dBase Files directly, then you already know what we are going to explore here and have a general idea by now as to how to send output data into external databases without linking them to MS-Access.

Sample SQL for External dBase Table.

Before going into that, let us take a closer look at the sample SQL that brings in data from a dBase Table through a Query, without linking the table into the MS-Access database.

NB:  If you don’t have a dBase Table, to try out these examples, you can create dBase Tables by exporting one or more of your Access Tables into a separate folder on your disk.  You don’t have to install a dBase Application on your machine. Necessary ODBC Driver Files are already installed by MS Office on your machine.

SELECT Employees.* FROM Employees IN 'C:\MydBase'[DBASE IV;];

The SELECT Query will return the entire records from the Employees.dbf Table from the dBase database ‘C:\MydBase’.  The text  [DBASE IV;] is the database type and version indicator.  The SQL IN 'C:\MydBase'[DBASE IV;]; clause creates a direct link to the Employees.dbf Table without a physical link.  That means the Employees.dbf data are available to other processes through this query only.

Throughout the above articles, we were discussing bringing data from external databases, without keeping them linked to Access.  This time we will explore how to update or add data to the external databases.

Updating Data into External dBase Table.

A sample SQL that updates an external dBase Table is given below:

UPDATE Products IN 'C:\MydBase'[DBASE 5.0;] SET Products.TARGET_LEV = 45 WHERE (((Products.TARGET_LEV)=40) AND ((Products.REORDER_LE)=10));

With the above SQL, we are updating the Products stock Target level to 45 from 40, for items with Re-order Level (Minimum Stock Level) is 10 and the current stock quantity target level is 40.

Appending Data into External dBase Table.

Let us append some data from Products_Tmp Table from the current MS-Access Database to the Products.dbf Table of C:\MydBase dBase Database.  The sample SQL is given below:

INSERT INTO Products
  SELECT Products_Tmp.*
  FROM Products_Tmp IN 'C:\MydBase'[DBASE 5.0;];

IN Clause and Query Property Setting

Source Database and Source Connect Str Properties.

Let us examine the Property Sheet of one of the above Queries to check for any indication about whether the SQL IN Clause setting is in there or not.

  1. Open one of the above Queries in Design View.

  2. Display the Property Sheet of the Query. Press F4 or ALT+Enter to display the property sheet and make sure that it is the Query Property Sheet. Under the Title of the Property Sheet, there will be a description: Selection Type Query Property.

  3. You may click on an empty area to the right of the Table on the Query Design surface to make sure that the Property Sheet displayed is Query's Property Sheet, not the Table or Query Column Property Sheet. Check the sample image given below.

  4. Check the Source Database and Source Connect Str Property Values. If you find it difficult to memorize the correct syntax of the IN Clause in the SQL then you can populate the respective values in these properties of the Query as shown. This will automatically insert the Connection String with the correct syntax in the SQL.

  5. You can find the correct syntax for Access, Excel, Paradox, and ODBC connection string for IBM iSeries machine, SQL Server, etc., from the above-quoted Articles.

Caution:

Even though the above methods provide some convenient way to manage external tables, without keeping them permanently linked to the MS-Access database, extensive use of this method can lead to issues at a later stage if you are not careful. It is important that you maintain some form of documentation of these Queries for safekeeping.

Constant Location Reference Issues?

Let us take the example of an external MS-Access database itself. The SQL given below appends some data into the Employees table in another Microsoft Access database on LAN Server directly. This is a routine process done daily or weekly etc.

INSERT INTO Employees IN 'T:\Sales\mdbFolder\Database1.accdb' 
SELECT Employees_tmp.*
FROM Employees_tmp;

Everything works just fine and you forgot about this specific Query or other Queries similar to this one. After about six month’s time you thought of shifting or copying the databases from the current location into another Folder on the Server (say T:\Export\mdbFolder), leaving a copy in the old folder as a backup, and installed in the new . . .\Export\ folder. Everything was found to work OK without triggering any error in the new location and the Users are also happy.

Your database has a few Queries with the above Connection Strings in their SQL, which never crossed your mind of attending to them and changing the SQL to point them correctly to the databases to the new location. The Queries will keep on servicing the Table in the old location . . .\Sales\. . . , instead of the Table in . . .\Export\. . . Location. The data missing problem when reported by the user may not trigger the Query IN Clause button in your mind immediately and you may be pulling your hair to find out what went wrong, wasting hours or days, till you arrive at the accident spot.

In spite of these drawbacks, it is a good way to use the external databases when needed only, if the frequency is minimal, rather than keeping them always attached to the FE. 

Share:

Dynamic Dlookup in Query Column

Introduction.

If we need only a single column value from a related table to incorporate into a Microsoft Access Query then we can use the Dlookup() function to bring that value into the Query Column. Normally we place that Table also into the Query's design surface, establish the link between the Primary Key of the main table and the Foreign Key of the other table and place the required field in 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 has 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 the 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 it every time.

Check the sample Query result image given below:


Applying Different Tax Rates

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 a revised sales tax rate.  We have to prepare some invoices with the previous year's sales tax rates and others with current-year rates.  That means the Dlookup() function will look like Dlookup(“TaxRate2005”,” “,” “) for a previous year and Dlookup(“TaxRate2006”,” “, “ “) for the current year.  The table name and criteria parameters are 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 TextBox and a Command button and let the user type the tax rate field name in the TextBox (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 the record source.  A sample image of the Query parameter Form is given below:

The Textbox name Tax on the above form.  With that in mind,;lkjh3 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 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:

Change Query Top Values Property with VBA-2

Continued from Last Week's Topic.

Through last week’s introduction, we have seen various ways the Top Value and other properties change the SQL string of a SELECT Query.  Now we will learn how to redefine the Query for the Top Values and other property changes. 

As I have mentioned earlier three types of Queries; SELECT, APPEND, and MAKE-TABLE only have the Top Values property.  SELECT and MAKE-TABLE queries have almost identical SQL string with DISTINCT, TOP nn, PERCENT clauses appearing immediately after the SELECT clause at the beginning of the SQL string. 

A sample SQL string of a make-table query is given below:

SELECT TOP 15 PERCENT SalesReportQ.* INTO chart
FROM SalesReportQ
ORDER BY SalesReportQ.Total DESC;

Unlike SELECT and MAKE-TABLE Queries APPEND Queries have the Top Values property settings inserted somewhere in the middle of the SQL string immediately after the SELECT clause. Check the sample SQL of Append Query given below:

INSERT INTO Table3 ( xID, Field1, Field2 )
SELECT DISTINCT TOP 17 PERCENT Table2.ID, Table2.Field1, Table2.Field2
FROM Table2
ORDER BY Table2.ID DESC;

Our VBA program scans through the SQL String to find the TOP Values property Clauses in the SQL String(wherever they appear), removes the existing settings, and insert changes as per input from the User.

First, we will create a form for the User to input Query Top Values property values and click a Command Button to redefine the SQL.

Image of a sample form is given below:

Two text boxes with the name Qry and TopVal, for Query name and for Top values parameters respectively, and a checkbox with the name Unik for Unique value selection.  The Top Values text box can be set with a number or a number with a percentage symbol (like 20 or 15%).  If the Unik checkbox is set then the query suppresses duplicate records based on the selected field values in the Query.

After setting the Query property values in the above controls the user should click the Command Button to redefine the SQL of the selected query in the Query Name control.  The Command Button's name is cmdRun (with the Caption: Modify Query). When the Command Button is clicked the cmdRun_Click() Event Procedure is run (the VBA Code is given below) and validates the input values in the controls above and calls the QryTopVal() function (with parameters: query name, Top Values property value, and Checkbox value) to redefine the Query based on the user inputs.

Form Module Code.

Private Sub cmdRun_Click()
Dim strQuery, strTopVal, bool As Boolean
Dim msg As String

On Error GoTo cmdRun_Click_Err

msg = ""
strQuery = Nz(Me![Qry], "")
If Len(strQuery) = 0 Then
   msg = "  *>>  Query Name not found." & vbCr
End If
strTopVal = Nz(Me![TopVal], 0)
If strTopVal = 0 Then
   msg = msg & "  *>>  Top Property Value not given."
End If
bool = Nz(Me![Unik], 0)
If Len(msg) > 0 Then
    msg = "Invalid Parameter Values:" & vbCr & vbCr & msg
    msg = msg & vbCr & vbCr & "Query not changed, Program Aborted...."
    MsgBox msg, , "cmdRun_Click()"
Else
    'Call the QryTopVal() Function to redefine the Query
    QryTopVal strQuery, strTopVal, bool
End If

cmdRun_Click_Exit:
Exit Sub

cmdRun_Click_Err:
MsgBox Err.Description, , "cmdRun_Click()"
Resume cmdRun_Click_Exit
End Sub

Copy and paste the above VBA Code into the Form Module and save the Form. Don't forget to name the Command Button as cmdRun.

The Main Function QryTopVal().

The main function QryTopVal() checks the Query Type (SELECT or APPEND or MAKE-TABLE) and if found valid then reads the SQL of the query.  Checks for the existence of Top Values and other Property settings and if they exist then remove them.  Redefines the query based on the Top Values and other property inputs from the user.

Copy and paste the following VBA Code of QryTopVal() into the Standard Module and save it:

Public Function QryTopVal(ByVal strQryName As String, _
                       ByVal TopValORPercent As String, _
                       Optional ByVal bulUnique As Boolean = False)
'--------------------------------------------------------------------
'Author : a.p.r. pillai
'Date   : Jun 2011
'Remarks: All Rights Reserved by www.msaccesstips.com
'Valid Query Types:
'  0 - SELECT
' 64 - APPEND
' 80 - MAKE TABLE
'--------------------------------------------------------------------
Dim strSQL1 As String, strSQL2 As String, strTopValue
Dim db As Database, qrydef As QueryDef, sql As String
Dim loc, qryType As Integer, locTop
Dim txt(1 To 3) As String, num
Dim J, xt, msg As String

On Error GoTo QryTopVal_Err

txt(1) = "DISTINCT"
txt(2) = "TOP"
txt(3) = "PERCENT"

Set db = CurrentDb
Set qrydef = db.QueryDefs(strQryName)
qryType = qrydef.Type

If qryType = 0 Or qryType = 64 Or qryType = 80 Then
   xt = qrydef.sql

   GoSub ParseSQL

   loc = InStr(1, TopValORPercent, "%")

   If loc > 0 Then
      TopValORPercent = Left(TopValORPercent, Len(TopValORPercent) - 1)
   End If

   If Val(TopValORPercent) = 0 Then
      sql = strSQL1 & strSQL2
   Else
      sql = strSQL1 & IIf(bulUnique, "DISTINCT ", "") & "TOP " & TopValORPercent & IIf(loc > 0, " PERCENT ", "") & strSQL2
   End If

   qrydef.sql = sql
   msg = "Query Definition of " & strQryName & vbCr & vbCr & "Changed successfully."
   MsgBox msg, , "QryTop()"
Else
   msg = strQryName & " - Invalid Query Type" & vbCr & vbCr
   msg = msg & "Valid Query Types: SELECT, APPEND and MAKE-TABLE"
   MsgBox msg, , "QryTop"
End If

QryTopVal_Exit:
Exit Function

ParseSQL:
For J = 1 To UBound(txt)
  xt = Replace(xt, txt(J), "", 1)
Next
  
  locTop = InStr(1, xt, "SELECT")
  num = Val(Mid(xt, locTop + 7))
  num = " " & Format(num) & " "
  strSQL1 = Left(xt, locTop + 7)
  xt = Right(xt, Len(xt) - (locTop + 7))
  xt = Replace(xt, num, "", 1, 1)
  strSQL2 = " " & xt
  locTop = InStr(1, strSQL2, "ORDER BY")
  If locTop = 0 Then
    MsgBox "ORDER BY Clause not found in Query.  Result may not be correct.", , "QryTopVal()"
  End If
Return

QryTopVal_Err:
MsgBox Err & " : " & Err.Description, , "QryTopVal()"
Resume QryTopVal_Exit

End Function

You may try the Code with sample Queries.

Share:

Change Query Top Values Property with VBA

Introduction.

We have learned how to use the Top Values-Property of Queries (the SELECT, MAKE-TABLE, and APPEND Queries where this property is applicable) in an earlier post.  Before going through this article I suggest you take a look at the earlier one given there.

The Queries Top Values-Property can be set only manually during design time.  You cannot address the Top Values-Property of the Query in VBA, to change its present value dynamically.  You cannot ask the User to open the Query in the design view and change the value every time when they want a different set of outputs.  Then what do we do to work with these values?

Sample SQL with TOP Property Setting.

When we change the Top Values property value manually MS-Access modifies the SQL of the Query to reflect that change.  Keeping this behavior of the Query in mind, we can play some tricks with VBA to manipulate the Query's SQL to get what we want, rather than looking for the Property to set the value.  But, before doing that let us examine and find out what happens to the SQL definition of the Query when you set Top Values and other Properties.

Here is a sample SQL of a SELECT Query with the Top Values-Property set with the Value 25.

SELECT TOP 25 Orders.OrderID, Orders.EmployeeID, Orders.OrderDate, Orders.RequiredDate, Orders.Freight
FROM Orders
ORDER BY Orders.Freight DESC;

As you can see in the above example; immediately after the SELECT clause the text TOP 25 is inserted in the SQL string indicating that the TOP Value Property of the Query is set with the value 25.  In the ORDER BY Clause, you can see that the Freight Column is sorted in Descending Order.  The result set of the Query is 25 records with the highest Freight Values in the Table.

When you want 25% of the Total records as output from the Orders Table then the Top Values property value must be set as 25%, rather than 25.  The SQL text changes to SELECT TOP 25 PERCENT . . . Sample SQL is given below:

SELECT TOP 25 PERCENT Orders.OrderID, Orders.EmployeeID, Orders.OrderDate, Orders.RequiredDate, Orders.Freight
FROM Orders
ORDER BY Orders.Freight DESC;

The next one that affects the record set is Unique Values-Property (valid values are Yes or No).  When it is set; suppresses duplicate records from the output displayed in the Datasheet. But, other field values that are not placed on the Query Column from the Table are not considered while excluding duplicate records.  The DISTINCT Clause is inserted in the SQL immediately after the SELECT Clause.  The modified sample SQL is given below after the Unique Value Property is set to Yes.

SELECT DISTINCT TOP 25 PERCENT Orders.OrderID, Orders.EmployeeID, Orders.OrderDate, Orders.RequiredDate, Orders.Freight
FROM Orders
ORDER BY Orders.Freight DESC;

There is one more Query Property Unique Records that can be set (valid values are Yes or No) to suppress duplicate records from the output.  When this is set with the value Yes, it suppresses duplicate records, based on values in all the fields in the source table, irrespective of their placement on the Query column.  In this case, the DISTINCT clause will be modified as DISTINCTROW in the SQL string.

SELECT DISTINCTROW TOP 25 PERCENT Orders.OrderID, Orders.EmployeeID, Orders.OrderDate, Orders.RequiredDate, Orders.Freight FROM Orders ORDER BY Orders.Freight DESC;

This property we will exclude from our VBA-based solution. As you can see from the above examples depending on the Users' requirements, we can add or remove any of these three sets of values (DISTINCT, TOP nn & PERCENT) to control the output for Reports.

Preparing for the VBA-based Solution.

Our methodology to modify the SQL is very simple to implement. Collect the Query Property values from the User through a TextBox and a Checkbox on a Form. Let the User click a Command Button to redefine the Query.

This will invoke the following actions to redefine the Query:

  1. Open the Query Definition and read the existing SQL String.

  2. Scan the SQL string and look for the text DISTINCT, TOP nn, and PERCENT.  If found, then remove them from the SQL String.

  3. Validate the input given by the User in the Textbox and checkbox and insert appropriate SQL Clauses in the SQL String.

  4. Update the modified SQL in the Query definition.

This article has become too long now.  Explaining the above four steps and introducing the VBA Routines may make it even longer.  We will complete this topic in the next blog post.

Earlier Post Link References:


Share:

TOP N RECORDS IN QUERY

Introduction.

We have seen the usage of different types of complicated Queries like the following:

Today we will learn how to define and extract the top 100 or whatever number of records or a certain percentage of the total records based on the values, in a particular Column.

Review of Rules of Queries.

You need to know only a few rules to work with this type of Query.

  1. You may select several Columns of data from the source for output.

  2. You must sort one or more columns of data in Ascending/Descending Order and the leftmost sorted column will pick the top valuation records.

  3. If the output values have duplicates (duplicate values in all columns in two or more records) then you can set the Unique Values Property to Yes (a DISTINCT clause in the SELECT statement) to suppress duplicate records.

  4. If the query has more than one Table/Query as the source and when duplicate records are found in the output; set the Unique Records Property to Yes (DISTINCTROW clause in the SELECT statement) to suppress duplicate records.

Create a Sample Query.

  1. Open a new database or one of your existing databases.

  2. Import the Order Details and Products Table from Northwind.mdb sample Database. The Products table is not directly used, but there is a lookup reference to this table in the Order Details table for Product Name.

  3. Open a new Query in SQL View (without selecting a Table/Query from the displayed list).

  4. Copy and paste the following SQL String into the SQL editing window and save the Query with the name Order_DetailsQ.

    SELECT TOP 100 [Order Details].ProductID, [Order Details].UnitPrice
    FROM [Order Details]
    WHERE ((([Order Details].OrderID) Between 10248 And 10300))
    ORDER BY [Order Details].UnitPrice DESC;
  5. Open the Query in Design View and check the order of placement of fields and the Sort Field.

  6. Right-click on an empty area above the column grid to display the Query Shortcut Menu and select the Properties… option to display the Property Sheet. Check the image below:

  7. Check the Top Values Property, that set to the value 100, which dictates the Query to select 100 records with the highest Unit Price values.

  8. Change the View of the Query into Datasheet View to display the output records.  See the image given below:

    The Order Details Table has several records of the same Product under different OrderIDs. We have purposely not included the OrderID field in the data column except in the criteria to select the records of OrderIDs between 10248 and 102300 and to pick some duplicate records.  As you can see in the image given above; there are several duplicate records of the same product in the output.  With the duplicate records, we can try out the Unique Values property settings.

    Eliminating Duplicate Records.

  9. Change the Top Values property value to All and change the Query into Datasheet View. The output will be about 150 records for OrderIDs between 10248 and 102300.

  10. Change the Query in Design View and display its Property Sheet.

  11. Set the Top Values property with 100 and Unique Values property to Yes.

  12. Change the Query in Datasheet View and inspect the output.

    Now the duplicate records are suppressed (29 of them) and the output is now only 71 records.  The next property Unique Records can be set to Yes to get the same result when data fields are placed from two or more Tables or Queries joined together in the Query design and duplicate records are found in the output; due to a one-to-many relationship.

    We have specified 100 records in the Top Values Property but the Unique Values property setting reduced the number of records to 71 after suppressing duplicates. 

  13. Change the Top Values Property setting from 100 to 25% and change the View into Datasheet View.

The percentage setting gives only one-fourth (18 records) of a Total of 71 records as output with the Unique Values setting to Yes or 39 records (one-fourth of about 150 records) with the Unique Values setting to No.

The Top Values Property sets can be a specific number or a percentage of Total Records.

Share:

Sub-Query in Query Column Expressions

Introduction

Queries are the main data processing component of the database systems.  Queries work behind the scene shaping the data into Reports and other forms of outputs.  Microsoft Access Users (mostly beginners) attempt to create the output for a Report, by chaining several Tables in Queries together and the report data are expected to form in one or two query steps.  This approach may not be the correct one because it will be difficult to get the proper output for the Report.

First, you must plan your Report by defining the layout, contents, grouping, summary, etc.  If several related tables are involved in organizing the required data then you may take smaller steps of joining a few tables or queries together in a Query.  Use this Query as input and combine it with other tables in the next step.  You may create intermediate tables and create Queries out of them for further processing of information.  In these steps, you may use Make-table, Append Table, Update, etc., to process the data.

When Report Requirement is Complicated.

When the Report contents are complicated and difficult to create in one go then my approach is to create a Report table and bring the data piece by piece from the source Table(s) with Queries/VBA Routines and add or update them into the Report Table before opening the Report.  These processing steps can be automated through Macros/VBA.

Necessary report parameters like date-range or filtering criteria values will be collected in a parameter table to use in data processing queries.  There will be options in the Parameter Form either to Re-run the Report creation procedure with changing parameter values or to open the existing Report in Preview/Print mode. 

Using Sub-Query in Criteria Row.

Here, we are trying to explore the usage of Sub-Queries in the Queries to filter or incorporate data from tables or from other Queries.

Let us look at a simple Query that uses a sub-query in the criteria section to filter data from the Orders Table.   In the Orders table, there are about 830 Orders ranging OrderIDs from 10248 to 11077.  We need to filter certain Groups of Order (say Order Numbers 10248,10254,10260,10263,10267,10272,10283) for review.

Following is an SQL of a sample Query that filters the above Orders without the use of a Sub-Query:

SELECT Orders.*
FROM Orders
WHERE (((Orders.OrderID) In (10248,10254,10260,10263,10267,10272,10283)));

The above Query does the job, but the problem is when we want a different set of Orders to be filtered then the Query's Criteria line needs to be modified physically to replace with a new set of Order Numbers to filter.  We cannot expect the User to do this task manually, instead, we must provide them with an option to key in the Order Numbers into a table (ParamTable with a single field: OrderNumber) and use it as criteria.  This method will facilitate the automatic detection of the change of values in the table at run time.  The User can simply type the Order Numbers in a Datasheet Form and click a Command Button to run the query with the changed order numbers.  With this method, we need a Sub-Query in the criteria row to compare the Order Numbers in the Paramtable with the Order Numbers in the Orders Table and filter data.

We will modify the Query to insert a Sub-Query in the Criteria Row to pull the values from the ParamTable and to use the OrderNumber field values as criteria. 

The modified SQL String of the Query is given below:

SELECT Orders.*
FROM Orders
WHERE (((Orders.OrderID) In (SELECT OrderNumber FROM OrderParam)));

The Sub-Query string in the Criteria Row is in Bold in the SQL above.

Sub_Query in a Query Column.

It is likely that you already came across the above sub-query before, but we are going to learn how to use a Sub-Query as an expression in a Query Column to incorporate values from a different table, related to the Query Source Table. This usage is not so common and it is very useful in difficult times.

When several tables are used in a Query with LEFT JOIN or RIGHT JOIN relationships it becomes difficult to link all the related tables this way to incorporate summary values of one table. This is more so when one-to-many relationships are involved.

We will use Orders and Order Details Tables from the Northwind.mdb sample database for our example. Import both these tables from the Northwind.mdb sample database from C:\Program Files\Microsoft Office\Office11\Samples\Northwind.mdb.

The sample Query (in normal style), given below, uses both the Tables in the Query, linked to the OrderID Field of both tables to create an Order-wise Summary from the Order Details Table.

SELECT Orders.OrderID,
 Orders.CustomerID,
 Sum((1-[Discount])*[UnitPrice]*[Quantity]) AS OrderVal
FROM Orders INNER JOIN [Order Details] ON Orders.OrderID = [Order Details].OrderID
GROUP BY Orders.OrderID, Orders.CustomerID;

The same result can be achieved without placing the Order Details Table in the Query design. We will write an expression in a separate Column using a Sub-Query to pull the summary Order-wise Total Value directly from the Order Details Table. Here is the example SQL String:

SELECT Orders.*,
    (SELECT  Sum((1-[Discount])*[UnitPrice]*[Quantity]) AS OrderValue
     FROM [Order Details] AS ODetails WHERE ([ODetails].[OrderID] = [Orders].[OrderID])
GROUP BY [ODetails].OrderID) AS OrderVal, [OrderVal]*0.12 AS Tax
FROM Orders;

There are several records in the Order Details table for a single order in the Orders Table.  Through the Sub-Query (Total Query) we sum up the Sale Value of each Order and places the result in its corresponding row in the output.  So, the Sub-Query runs in a separate Column as an expression independently for each row in the Orders table for the output.

The new column name: OrderValue created can be part of other expressions and we have calculated the Tax value 12% of Order Value, in a separate column.

Let us take a closer look at the Sub-Query.

  1. The SELECT clause uses only one output column (Sum((1-[Discount])*[UnitPrice]*[Quantity]) AS OrderValue) and the expression is named as OrderValue.  You should not use more than one column in the SELECT clause.
  2. In the FROM clause, the Order Details Table is given a new name (ODetails) and this name is used to qualify the OrderID field in the WHERE clause.  The OrderID field appears in both Orders and Order Details Tables.
  3. The WHERE clause in the Sub-Query is necessary to match the OrderIDs of both tables and place the calculated values in their matching row of Order Records.

Earlier Post Link References:

Share:

Memo field and data filtering

Introduction.

We design tables carefully to organize information properly so that we can retrieve them easily through search, filter, etc.  If you look at the Employees table in the Northwind.mdb sample database, you can see that even an employee's name is split into three parts (Title, First Name & Last Name) and stored in three different fields so that we can work with each piece of information separately.  The name fields are defined to a specific length taking into consideration the size of the source information.

When it comes to recording employees' qualifications or work experience, we cannot define the field size to a specific length because the length of information may vary from case to case.  This is where we think of the Memo field type.  A memo field is a free-form text field where you can record descriptive information of various lengths.

When we want to extract information for reports or views we never think of using the Memo field contents because it has information in an unpredictable form and is considered difficult to work with besides displaying/printing its contents.

Even though Memo Field has only limited flexibility in data filter operations, we can filter records based on specific text spread all over different locations in the memo field.

We can try a few examples with Memo Field data from the Employees Table of Northwind.mdb sample database.

Prepare for a Trial Run.

  1. Import the Employees Table from the sample database C:\Program Files\Microsoft Office\Office\Samples\Northwind.mdb.

  2. Open the Employees Table in the datasheet view.

  3. Move the horizontal scrollbar at the bottom to the right, so that the Notes Memo Field contents are visible to you.

  4. Point the mouse at the left border of the table at the intersection of the two rows so that the mouse pointer turns into a cross.

  5. Click and drag down to increase the row size bigger so that the Notes field contents can be viewed properly.

    Now, if you look at the qualification information of each employee record you can see that most of them have a BA degree but the text "BA" is not positioned at a specific location in the Memo Field. If you want to filter all employee records with a BA degree, how do we do it?

    Let us do it directly on the datasheet view first, before we consider writing a Query to filter data based on the text in the Memo Field.

  6. Highlight the letters BA in any one of the records and Right-click on the highlighted text.

    A shortcut menu is displayed and the suggested options for filtering data from the Memo Field are Contains "BA" or Does Not Contain "BA".

  7. Click on the Contains "BA" option to filter the records with the text "BA" appearing anywhere within the memo field.

If you want to filter records this way for printing a Report then we must create Queries to filter data based on the text in Memo Field.  You can use the Like Operator combined with AND, OR logical operators.

Copy and paste the following SQL Strings into the SQL Editing Window of new Queries and save them with the suggested names:

Query Name:  Employee_BAQ

SELECT Employees.LastName, Employees.FirstName, Employees.Notes
FROM Employees
WHERE (((Employees.Notes) Like "*BA*"));

The output of this Query will include a record of an employee with an MBA Degree too, because of the text 'BA' in MBA. If you want to exclude this record, then modify the criteria with space immediately after the first asterisk like '* BA*'.

Query Name:   Employee_BA_BSCQ

SELECT Employees.LastName, Employees.FirstName, Employees.Notes
FROM Employees
WHERE (((Employees.Notes) Like "* BA*")) OR (((Employees.Notes) Like "*BSC*"));

The above query gives an example of the usage of the logical operator OR to filter data of employees with graduation in BA or BSC.

Query Name:   Employee_BA_BSCQ

SELECT Employees.LastName, Employees.FirstName, Employees.Notes
FROM Employees
WHERE (((Employees.Notes) Like "* BA*" And (Employees.Notes) Like "*psychology*"));

The above example shows the usage of the logical operator AND and filters the records of the employees with graduation in BA in Psychology.

Earlier Post Link References:

Share:

Auto Numbering In Query Column

Introduction

Find New Auto-Numbers in Query Column Version-2 on this link.

For creating "Running Sum Values in Query-Column" visit the following link:

Running Sum in MS-Access Query.

We know how to create an Auto-number Field in a Table to generate Unique Sequence numbers automatically for the records added to the Table. We know how to create Sequence Numbers for data lines on Reports.

On The Reports.

On Reports, create a TextBox in the Detail Section of the Report, write the expression =1 in the Control Source Property and, change the Running Sum Property Value to Over All or Over Group. If you need sequence numbers for each Group separately, depending on the Sorting and Grouping settings on the Report, then the Over Group option must be set in the Property otherwise set the Over All value, for continuous numbers from the start of the Report to the End.

If you want to create a Running Sum value of a Field, like Quantity or Total Price, then set the Running Sum Property value as explained above. For more details on Running Sum as well as creating Page-wise Totals on Access Reports visit the Page with the Title: MS-Access Report and Page Totals.

In The Query Column.

But, Auto-numbering in the Query Column looks somewhat strange to ask for, unless you want to use the Query result for display purposes or the output created from that should have sequence numbers for some reason. 

Products Category Group-level sequence numbers or for creating Rank List for students based on their obtained marks and so on.

Or after filtering the records in the Query the Auto-number field values gone out of sequence.

Anyway, this requirement was raised by a participant in an MS-Access Users Forum on the Net and nobody (including me) could give a clear-cut solution except for some alternatives. I chipped in with a solution of my own, even though I was not happy with that either.

The Access User who raised the question in the Forum made direct contact by sending an e-mail to me asking for a solution.

This made me think again on that topic and did a few trial runs of a few simple methods. Finally, I could come up with a Function that can do the trick and I am presenting it here so that you can also use it if you really need it.

Need Trial and Error Runs.

It is important to know the usage of the QrySeq() Function in a new Column of Query to create Sequence Numbers. The Function must be called with a few Parameter Values using the value(s) from the Query Column(s) itself. So, before presenting the VBA Code of the Function I will give some details of the Parameters.

Usage of the Function in the Query Column is as shown below:

SRLNO: QrySeq([ORDERID]"[ORDERID]""QUERY4")

The QrySeq() Function needs three Parameters.

  1. The First Parameter must be Unique Values available from any Column in the Query.
  2. The second Parameter is the Column Name of the first parameter in Quotes.
  3. The third Parameter is the Name of the Query, from which you call the Function.

The Query, from where the QrySeq() Function is called should have a column of Unique Values, like Autonumber or Primary Key Field. If this is not readily available, then create a Column by joining two or more existing fields (like NewColumn:([OrderlD] & [ShippName] & [RequiredDate] & [Quantity] from the existing column values and ensure that this will form Unique values in all records and pass this Column value ([NewColumn]) as the first Parameter.

The first Parameter Column Name must be passed to the Function in Quotes ("[NewColumn]") as the second parameter.

The Name of the Query must be passed as the third parameter.

NB: Ensure that you save the Query first, after every change to the design of the Query, before opening it in Normal View, to create the Sequence Numbers correctly.

The QrySeq() Function Code

Now then, the simple rules are in place and it is time to try out the Function.

  1. Copy and Paste the following VBA Code into a Standard Module in your Database:

    Option Compare Database
    Option Explicit
    
    Dim varArray() As Variant, i As Long
    
    Public Function QrySeq(ByVal fldvalue, ByVal fldName As String, ByVal QryName As String) As Long
    '-------------------------------------------------------------------
    'Purpose: Create Sequence Numbers in Query in a new Column
    'Author : a.p.r. pillai
    'Date : Dec. 2009
    'All Rights Reserved by www.msaccesstips.com
    '-------------------------------------------------------------------
    'Parameter values
    '-------------------------------------------------------------------
    '1 : Column Value - must be unique Values from the Query
    '2 : Column Name  - the Field Name from Unique Value Taken
    '3 : Query Name   - Name of the Query this Function is Called from
    '-------------------------------------------------------------------
    'Limitations - Function must be called with a Unique Field Value
    '            - as First Parameter
    '            - Need to Save the Query after change before opening
    '            - in normal View.
    '-------------------------------------------------------------------
    Dim k As Long
    On Error GoTo QrySeq_Err
    
    restart:
    If i = 0 Or DCount("*", QryName) <> i Then
    Dim j As Long, db As Database, rst As Recordset
    
    i = DCount("*", QryName)
    ReDim varArray(1 To i, 1 To 3) As Variant
    Set db = CurrentDb
    Set rst = db.OpenRecordset(QryName, dbOpenDynaset)
    For j = 1 To i
        varArray(j, 1) = rst.Fields(fldName).Value
        varArray(j, 2) = j
        varArray(j, 3) = fldName
        rst.MoveNext
    Next
    rst.Close
    End If
    
    If varArray(1, 3) & varArray(1, 1) <> (fldName & DLookup(fldName, QryName)) Then
        i = 0
        GoTo restart
    End If
    
    For k = 1 To i
    If varArray(k, 1) = fldvalue Then
        QrySeq = varArray(k, 2)
        Exit Function
    End If
    Next
    
    QrySeq_Exit:
    Exit Function
    
    QrySeq_Err:
    MsgBox Err & " : " & Err.Description, , "QrySeqQ"
    Resume QrySeq_Exit
    
    End Function

    The Sample Trial Run

  2. Import the Orders Table from C:\Program Files\Microsoft Office\Office11\Samples\Northwind.mdb sample database.
  3. Copy and Paste the following SQL String into the SQL Editing View of a New Query and save the Query with the Name: AutoNumberQuery:
    SELECT Orders.*, QrySeq([OrderID],"OrderID","AutoNumberQuery") AS SRLNO
    FROM Orders;
    
  4. Select Save from File Menu or click on the Save Toolbar Button.
  5. Open the Query in the normal view.

Check the SRLNO Column for Sequence Numbers.

Here, the OrderID in the Orders Table has unique field values and we could easily get away with the Sequence Numbers correctly in SRLNO Column.

Let us pretend for a moment that we don't have a single field with Unique Values in the Query. We must create a Column with Unique Values by joining two or more Columns available in the Query and pass it to the QrySeq() Function.

Let us try such an example with the Orders Table.

  1. Copy and Paste the following SQL String into a new Query and Save the Query with the name AutoNumberQuery2.
    SELECT Orders.*, [ShipName] & [RequiredDate] AS NewColumn, QrySeq([NewColumn],"NewColumn","AutoNumberQuery2") AS SRLNO
    FROM Orders;
  2. Open the Query in normal View to check whether the Serial Numbers were created correctly or not.

Ensuring Accuracy

When there are hundreds/Thousands of records in the Query it is difficult to check whether the Column Values we have passed to the Function are really unique and the Serial Numbers generated have no duplicates in them by manually checking through the records. Instead, we will take a Count of Serial Numbers appearing more than once in the Records, if any, with the use of a Total Query using AutoNumberQuery2 as the Source.

  1. Create a new Query uses the following SQL String and name the new Query as DuplicatesCheckQ:
    SELECT AutoNumberQuery2.SRLNO,
     Count(AutoNumberQuery2.SRLNO) AS CountOfSRLNO
    FROM AutoNumberQuery2
    GROUP BY AutoNumberQuery2.SRLNO
    HAVING (((Count(AutoNumberQuery2.SRLNO))>1));
    
  2. Open DuplicatesCheckQ Query in Normal View.

You will find the following result showing SRLNO Column is having the same number appearing more than once in the records indicating that the Unique Column Values we have created for the Function are not really Unique and have duplicates in them.

This can be rectified only by adding more Column Values to the NewColumn expression to eliminate the chance of ending up with duplicates.

This method is only an alternative in the absence of an AutoNumber or Primary Key field Values and not with a 100% percent success rate because when you add more records to the Source Table it is likely that it can fail again. In this case, the only solution is to join more fields to the expression in NewColumn so that we can reduce the chance of failures.

Now, to correct the above Query adds the [Freight] Value Column also to the NewColumn expression. Or Copy and paste the following SQL String into the AutoNumberQuery2 Query overwrites the earlier SQL string in there and save the Query.

SELECT Orders.*,
 [ShipName] & [RequiredDate] & [Freight] AS NewColumn,
 QrySeq([NewColumn],
"NewColumn";,"AutoNumberQuery2") AS SRLNO
FROM Orders;

Open the DuplicatesCheckQ Query again to check for duplicates. If the result is empty, then the Sequence Numbers generated will be correct.

Found Different Method, Share it With me.

If you have a better solution to this, then please share it with me too. I don't need a refined version of the above Code or method, but a different approach to arrive at the same or better result.

Next:

Autonumber with Date and Sequence Number.

Download


Download Demo QryAutoNum.zip



  1. Auto-Numbering in Query Column
  2. Product Group Sequence with Auto-Numbers.
  3. Preparing Rank List.
  4. Auto-Number with Date and Sequence Number.
  5. Auto-Number with Date and Sequence Number-2.
Share:

Multiple Parameters For Query

Introduction.

Queries are an essential element in data processing and we use them a lot in various ways. While creating Queries the main issue we are faced with is how to filter data in a user-friendly manner and make things work effortlessly for the User. We use several methods to facilitate the user to pass values as criteria to the Queries.

  1. Creating Parameter Queries and inserting Variables (like [Enter Sales Date]) in Query's Criteria row, so that the Query will prompt for Parameter Values and the User can Key-in them directly and filter records. The Data Type for the Parameter Variable can be defined by selecting the Parameters. . . Option from the Query Menu when you are in the Design view of the Query.

  2. Creates TextBoxes or Combo Boxes on the Form and the User fills in values into them and runs the Report or Data views. The underlying Queries will have a reference to the TextBoxes or Combo Boxes on the Form in the Criteria Row, like Forms![MyForm]![myDateCombo], and based on the values in them, the data filtering takes place for Reports or Views.

  3. Another way of selecting records is based on a range of Values. For example, filtering Sales records for a certain period and the criteria set in the Query for the Sales Date will be something like Between #01/01/2008# AND #03/31/2008# if the values are used in Constant form. But, these values also can be passed from TextBoxes from a Form too.

    What I prefer to do in these cases, creates a small table (let us call it, a Parameter Table) with one record and two fields for StartDate and EndDate and create a Datasheet Form and place it as a Sub-Form on the Main Form so that theUser can conveniently key in the date range values into the Table.

    This table will be included in the main Query and the StartDate, and EndDate fields are placed in the Criteria row with the expression Between [StartDate] AND [EndDate]. It is important to see that this Parameter table has only one record in it otherwise the records selected from the main table will be doubled if the parameter table has two records. We can control this by setting the Allow Additions Property Value, of the Data Sheet Form, to No so that the user is prevented from adding more records by mistake.

    When the user clicks a button in the Report or for other outputs based on this date ranges we can run the Query after refreshing the Parameter Sub-Form to update the changed value in the table.

  4. The above example, asks for all the data between StartDate and Update. But there are times that we need data, the intermittent values like Employee Codes 1, 5, 7, 8, and we are forced to input the Code in the criteria row in one of three ways like the sample image given below:

Query Parameter Input Methods

I would like to present here another method that I use to provide the Users to select Parameter Values for Reports by putting check marks in the Parameter Table.

Assume that our Company has Branch Offices across the Country and the Management may ask for Reports on selected Branches. Since Branch Names are constant values all we need to do is to select the required Branches by putting check marks on their side and the selected cases can be used as criteria for filtering Data.

To have a closer look at this method and for simplicity, we will use the List of Months for our example and see how the selected Months are used in the Criteria of the Main Query. The Image of the List of Months presented to the user in a Datasheet Form (as a Sub-Form on the Main Form) is given below:

We need two Queries, one to filter the selected months from the list and the second the Main Query in which we will use the Values from the first Query as a Parameter to filter Data for the Report. Our first Query must come out with the result values 3,6,9 & 12 as per the Month selection shown on the image above. The following SQL string is used for this purpose:

Query Name: Month_ParamQ

SELECT Month_Parameter.MTH
FROM Month_Parameter
WHERE (((Month_Parameter.[SELECT])=True));

When the User puts check marks on the Parameter screen the selection may not immediately update in the underlying Month_Parameter Table. To update the change we have to Refresh the Month_Parameter Sub-Form before opening the Report that pulls data from the Main Query that uses the above Query as criteria. For that, we have written a statement on the On_Click() Event Procedure of the Print Preview Command Button as below.

Private Sub cmdPreview_Click()
     Me.Month_Parameter.Form.Refresh
     DoCmd.OpenReport "myNewReport", acViewPreview
End Sub

Now, how the selected months filtered in the Month_ParamQ can be used in the Main Query as criteria? It is easy, to look at the third method we have used as criteria in the first Image given above. I will repeat it here below:

IN(1,5,7,8)

Here, we will compare the EmployeeID values, with the number 1,5,7,8 and select records that match any of these numbers as output.

Similarly, all we need to do here in the Main Query is to write this as a Sub_Query in the Criteria Row to use the Month Values from the Month_ParamQ. The above criteria clause, when written in the form of a sub-query will look like the following:

IN(SELECT MTH FROM MONTH_PARAMQ)

The User doesn't have to type the Parameter values for the Report, only put check marks on the required items, click a Button and the Report is ready.

Share:

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