Learn Microsoft Access Advanced Programming Techniques, Tips and Tricks.

Showing posts with label Records. Show all posts
Showing posts with label Records. Show all posts

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:

GetRows Function and Exporting Data

Introduction

We are going to create a useful data export utility with the GetRows() method of the Recordset Object. The GetRows method is used for loading the entire set of data from the table into memory in a doubly dimensioned Variant Array with a single statement. Let us try it with an example to see how this is done. An image of a sample table is given below and we will see how this will look like in memory when loaded with the help of the GetRows() method of the Recordset Object:

Table: Employees
ID Name BirthDate Height Weight
1 Nancy 12/10/1980 164 58
2 Peter 05/07/1975 180 80
3 Linda 17/11/1982 170 60

The VBA Code.

The following sample VBA Routine loads the above data into memory and a listing is dumped in the Debug Window:

Public Function Test(ByVal tblName As String)
Dim db As Database, rst As Recordset, varData As Variant
Dim intFields As Integer, intRecords As Integer, j As Integer, k As Integer
Dim rec As String, fld_type As Integer

Set db = CurrentDb
Set rst = db.OpenRecordset(tblName, dbOpenTable)
j = rst.RecordCount - 1
k = rst.Fields.Count - 1

varData = rst.GetRows(j + 1)

For intRecords = 0 To j
    rec = ""
    For intFields = 0 To k
    fld_type = rst.Fields(intFields).Type

    If fld_type = 11 Or fld_type = 12 Then
      GoTo nextField
    End If
      rec = rec & varData(intFields, intRecords) & ","
nextField:
    Next
    rec = Left(rec, Len(rec) - 1)
    Debug.Print rec
Next
rst.Close
Set rst = Nothing
Set db = Nothing
End Function

The arrangement of records in memory in a two-dimensional array looks like the following:

1 2 3
Nancy Peter Linda
12/10/1980 05/07/1975 17/11/1982
164 180 170
58 80 60

The Memory Image of the Data.

The records are not arranged in row order as they appear in the datasheet view, they are loaded in columns instead.  So, after loading the data in memory we must know how to address the two-dimensional array to access each record in the correct order to output the data.  Each field value is separated with a comma in the listing provided in the Debug window.

Normally, in a two-dimensional array, the first index value of the array is the row number and the second one is the column number.  But, in this case, the first index value is the Field order Number and the second value is the Record Number.  You can check the sample data arrangement in the memory shown above.

Export Data in Text Format

We will write a small utility program to export any MS-Access Table into a comma-delimited Text/CSV File, so that the data can be easily transported through the internet or to import into other applications.

The VBA code of the program is given below:

Public Function CreateDelimited(ByVal xtableName As String, ByVal txtFilePath As String)
'-----------------------------------------------------
'Utility: CreateDelimited()
'Author : a.p.r.pillai
'Date   : Dec. 2010
'Purpose: Create Comma Delimited Text File from Table 
'Rights : All Rights Reserved by www.msaccesstips.com
'-----------------------------------------------------
Dim db As Database, rst As Recordset
Dim varTable() As Variant, j As Long, k As Long
Dim rec As String, fld_type As Integer
Dim intRecords As Integer, intFields As Integer

Set db = CurrentDb
Set rst = db.OpenRecordset(xtableName, dbOpenTable)
varTable = rst.GetRows(rst.RecordCount)
k = rst.Fields.Count - 1
j = rst.RecordCount - 1

Open txtFilePath For Output As #1
rec = ""
For intFields = 0 To k
   fld_type = rst.Fields(intFields).Type
        If fld_type = 11 Or fld_type = 12 Then GoTo nextField
   rec = rec & Chr$(34) & rst.Fields(intFields).Name & Chr$(34) & ","
nextField:
Next
rec = Left(rec, Len(rec) - 1)
Print #1, rec
For intRecords = 0 To j
    rec = ""
    For intFields = 0 To k
        fld_type = rst.Fields(intFields).Type
        If fld_type = 11 Or fld_type = 12 Then GoTo Next_Field
        rec = rec & IIf(fld_type = 10, Chr$(34) & varTable(intFields, intRecords) & Chr$(34), varTable(intFields, intRecords)) & ","
Next_Field:
        Next: rec = Left(rec, Len(rec) - 1)
        Print #1, rec
Next
Close #1
rst.Close

Set rst = Nothing
Set db = Nothing

End Function

The Utility can be called from a Command Button Click Event procedure after setting the Table name and the target file pathname in text boxes.  You can test the utility by calling it from the Debug Window (Immediate Window) directly as given below:

CreateDelimited "Products", "C:\Temp\Products.txt"

NB: If MEMO or Photo Fields are present in the Table they are excluded from the output file.

The target file extension can be either .TXT or .CSV.

Earlier Post Link References:

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