Learn Microsoft Access Advanced Programming Techniques, Tips and Tricks.

Easy-Read Reports

Introduction.

When Computer Reports; like Accounting Ledger Statements or Purchase Invoices are printed with closely positioned lines. It is easy to read if the alternate line background is shaded with a light color.  Normally, pre-printed stationery is used for this purpose. Line-Printers will print 6 lines of data within a one-inch space vertically.  To print headlines in bold the double-strike method is used (the hammer will strike a character twice) and this is the only enhanced printing style available, as far as the Line Printers are concerned.

The Line-Printer-based Reports were designed on graph-paper-like sheets and write codes to position Headings, data lines, and summaries to position them properly on Report stationery.

A4 (8.5 x 11 inch) size paper will have 66 lines of print positions vertically. Out of this, one inch top and half an inch bottom margin space are left out while printing the alternate data print positions with green color like the sample image given below:

A4 size paper has 80 print positions across when 10 characters per inch (pitch) font size is used. This can be increased to 96 characters if 12 characters per inch character size are used.

This was general information about computer stationery. Reports are designed for Line Printers keeping these specifications in mind.  If necessary, we can design reports with detailed section height and the text box control's height in one-sixth of an inch in plain paper stationery.

Light Shading of Alternate Report Data Lines

We will try a small trick to print alternate print lines with the shaded background so that users can read the contents very easily. We don't need pre-printed stationery for this and we will prepare shaded background while printing the report itself.

We can design a Quick Report and write a few lines of VBA Code on the class module of the Report. If you already have a Report with closely printed detail lines you can skip to step 3 given below.

  1. Import Products Table from MS-Access sample database Northwind.mdb

  2. Use the Report Wizard to design a Tabular Report with the Products Table like the sample image given below:

  3. Open the Report in Design View.

  4. Select all the controls on the Detail Section of the Report and drag them to the right to get enough space to draw a Text Box on the left side to display Serial Numbers on the Report Lines.  Drag the heading lines and position them to the right.

  5. Draw a Text Box on the left side and write the expression =1 in the Control Source Property.  Change the Name Property Value to SRL.

  6. Change the Running Sum Property Value to Over All.

  7. Create a Label control at the Page Header above the Text Box and change the Caption to SRL (for Serial Number).

  8. Select all the controls in the Detail Section together and display the Property Sheet (F4 or Alt+Enter).

  9. Change the Top Property Value to 0.  All the controls will be shifted and positioned at the top edge of the Detail Section.

  10. Select the Rectangle Tool from the Toolbox and draw a rectangle around all the text boxes in the Detail Section (see the design view image above).

  11. Display the Property Sheet of Rectangle (F4) and change the Name Property Value to Box1.

  12. Select the Send-to-Back option from Arrange Menu to position the rectangle behind the text box controls.

  13. Reduce the Detail Section height so that there is no empty space below the TextBox controls.

  14. Display the VBA Code Module of the Report (ALT+F11).

  15. Copy and paste the following lines of VBA Code into the Code Module and save the Report:

    The Report Module VBA Code.

    Private Sub Detail_Format(Cancel As Integer, FormatCount As Integer)
    Dim xSrl
    xSrl = [SRL]
    If xSrl / 2 = Int(xSrl / 2) Then
       [Box1].BackColor = &HCCC8C2
    Else
       [Box1].BackColor = &HFFFFFF
    End If
    End Sub
    
  16. Open the report in Print Preview.  You will find the result as shown in the report image at the top of this page.

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:

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