Learn Microsoft Access Advanced Programming Techniques, Tips and Tricks.

Thursday, June 28, 2012

Defining Pages on Form

Introduction.

When designing a form, we usually place controls within the visible area of the screen for ease of use. However, an Access form can actually be as large as 22 x 22 inches, giving you plenty of real estate to work with. The challenge is not in placing controls on this large surface but in arranging them in a well-organized way. Without careful planning, the form may feel cluttered and inconvenient for users to navigate.

Page Usage Plan.

Let’s plan a four-page layout on a sample form to experiment with control placement and resizing. Assuming the visible area of the form is approximately 10 inches wide, we can define two logical pages side by side, each about 10 inches wide. Then, leaving about 5 inches from the top of the form, we can define another two pages below the first row. The diagram below illustrates this four-page layout for quick reference in our project.

We have planned four logical page areas as shown above. Physically, however, there are only two pages:

  • The first-page area spans the top, divided into two segments.

    • The first segment (logical page 1) starts at coordinates (0,0) — 0 inches from the left and 0 inches from the top of the form.

    • The second segment (logical page 2, top right) starts at coordinates (10,0) — 10 inches from the left and 0 inches from the top.

Each logical page is approximately 10 inches wide and 5 inches tall. For the macro that moves controls between pages, we only need to specify the top-left corner coordinates of each logical page.

  • The second logical page area (top right) begins at (10,0).

  • The command buttons located at the bottom-right corner of each logical page will run a macro to jump between pages.

The Page-Break control.

The dotted line on the left at the 5-inch vertical position is a Page Break control, inserted from the Toolbox, to define the second physical page area (which contains the third and fourth logical pages).

  • The third logical page (first segment of the second physical page) starts at 0 inches from the left and 0 inches vertically on the second physical page (i.e., 5 inches down from the top of the form).

  • The fourth logical page (second segment of the second physical page) starts at 10 inches from the left and 0 inches vertically on the second physical page.

The 10-inch width and 5-inch height for logical pages are arbitrarily chosen. You may adjust them if the pages overlap on your screen. Using the same rules, you can define additional logical pages on the form if needed.

The Page Navigation Plan.

Clicking on the first Command Button moves the focus to the second page at the top-right corner. The Command Button on this page will send the focus to the bottom-left page, and the button there will move the focus to the bottom-right page. Finally, the Command Button on the bottom-right page will bring the focus back to the top-left page, completing the loop.

Tip: You can also connect the macro to the Lost_Focus() event of the last textbox or control on each logical page. This way, when the user presses the Tab key, the focus will automatically move from one page to the next without needing to click a Command Button.

Now that the master plan and diagram are ready, we can implement them on a form. Let’s start by writing the macros to control the Command Buttons.

Create Macros.

  1. Select Macro from the Create menu to open a new Macro in the design view.

  2. Click on the Macro Names control to open the Name column of the macro.

  3. Select the first row in the Name column and type Page1-1.

  4. Select GotoPage from the drop-down control in the Action column.

  5. Select the Arguments column.

  6. Type 1 in the Page Number Action Arguments property below.

  7. Type 0 in the Right property and 0 in the Down property.

  8. Create the other three lines with the Argument values as shown in the image below:

  9. Save and close the Macro with the name MacPages.

  10. The Form Design.

  11. Open a new Form in Design View.

  12. Display the Property Sheet (F4).

  13. Click on the top left corner of the Form (Access2003) to select the Form’s Property Sheet or select Form in the Selection Type box (Access2007) of the Property sheet.

  14. Change the Width Property value of the Form to 20 inches.

  15. Click on the Detail Section to display its property sheet.

  16. Change the Height Property Value to 10 inches.

  17. Select the Page-break Control from the Toolbox.

  18. Find the 5-inch position from the left side Scale and click near the left border on the Detail Section to place the Page-break control there.

  19. Create a Textbox control, about half an inch down on the top left corner of the Form, and change the child label Caption value to Page-1.

  20. Create a Command Button below the Textbox and change the following property values as shown below:

    • Caption:  Go to 2
    • On Click:  MacPages.Page1-2

      Tip: You may select the Macro Name from the drop-down list to avoid typing mistakes.

  21. Create a second Textbox to the right of the first one, about half an inch to the right of the 10-inch scale location on top of the Form, and change the child label Caption to Page-2.

  22. Create a Command Button below the Text and change the following property values as shown below:

    • Caption:  Go to 3
    • On Click:  MacPages.Page2-1
  23. Create a Textbox below the Page-break control and change the child label Caption to Page-3.

  24. Create a Command Button below the Textbox and change the following property values as shown below:

    • Caption:  Go to 4
    • On Click:  MacPages.Page2-2
  25. Create a Textbox after the 10-inch location to the right and change the child label Caption to Page-4.

  26. Create a Command Button below the Textbox and change the following property values as given below:

    • Caption:  Go to 1
    • On Click:  MacPages.Page1-1
  27. Save the Form with a name.

  28. Test Run the Form.

  29. Open the Form in normal view and click on the Command Button to jump to the second page to the right.

    You will find that the form jumps to the second logical page to the right, and the Textbox on this page is the active control.

  30. Try clicking on other Command Buttons to transfer control from one page to the next.

In all cases, you will find that the textbox on the active logical page is the active control.

Tuesday, June 12, 2012

Accounting Year Week Calculations

Introduction.

Many companies maintain their Accounting Year from April 1 to March 31 of the following year. If you need a weekly analysis of sales or other activities, the challenge is that the standard DatePart() function in Microsoft Access calculates week numbers starting from January 1, not from April 1. For accounting purposes, April 1–7 should be considered Week 1, April 8–14 Week 2, and so on, regardless of the calendar week number.

We have the built-in Function DatePart() in Microsoft Access to calculate Week numbers based on the activity date provided to the function as a parameter.  Let us try an example of the DatePart() function directly on the Debug Window.

The date will be passed in dd-mm-yyyy format, and Sunday is taken as the first day of the week. The VBA Constant vbSunday represents the numeric value 1.

dt = DateValue("01-04-2011")
? DatePart("ww",dt,vbSunday)

Result: 14

The built-in DatePart() Function returns week number 14 instead of 1 for the accounting week period of April 1–7. This result can fluctuate between 13 and 14, depending on the first day of the week (the second parameter in the function, vbSunday in this case) and the year. For example, using DatePart() April 1, 2006, returns week 13, not week 1, which shows why an adjustment is needed to calculate accounting week numbers accurately starting from April 1.

To create a weekly Sales Graph for the first quarter of the accounting year (the first 13 weeks covering April, May, and June), we first need to convert the sales dates into their corresponding week numbers. This allows us to aggregate the sales values into weekly totals for the chart.

In short, the DatePart() function cannot be used directly to calculate Accounting months or weeks without some modifications. We can use the DatePart() function within our own Code to modify the output we want.

Function: AccWeek().

I have created a function, AccWeek(), to calculate week numbers for an accounting year running from April 1 to March 31. This function is primarily designed to be called from a query column, with an activity date (such as a sale date, payment date, etc.) as the parameter, to return the corresponding accounting week number. You can also use this function in VBA code, on a form, report, or anywhere else you need to determine the accounting week.

Copy and paste the following Code into a Standard Module in your Database and save it:

Public Function AccWeek(ByVal accDate As Date) As Integer
'--------------------------------------------------------------
'Author : a.p.r.pillai
'Date   : June 2012
'All Rights Reserved by www.msaccesstips.com
'--------------------------------------------------------------
Dim wkdayStart As Integer, wk As Integer, wkout As Integer
Dim accStart As Date, wksave As Integer, accStart1, accStart2

On Error GoTo AccWeek_Err
'First day of the week is taken Sunday as default
'If change is needed in your area please change the next line
wkdayStart = vbSunday
'calculate week number with built-in function
wk = DatePart("ww", accDate, wkdayStart)
'modify the week number according to accounting period
wksave = IIf(wk = 13 And ((Year(accDate) - 1) Mod 4) = 0, wk + 1, 13)
Select Case wk
      Case Is <= 13, 14
         wkout = DatePart("ww", DateValue("31-12-" & Year(accDate)), vbSunday) - wksave + wk
      Case Is > wksave
         wkout = wk - wksave
End Select

accStart1 = "01-04-" & Year(accDate)
accStart2 = "08-04-" & Year(accDate)

'Overlapped Week days check and reset week to 1
If (accDate >= accStart1) And (accDate < accStart2) Then
   wk = DatePart("ww", accDate, vbSunday)
   If wk > 1 Then
     wkout = 1
   End If
End If
AccWeek = wkout

AccWeek_Exit:
Exit Function

AccWeek_Err
MsgBox Err.Description, , "AccWeek()"
Resume AccWeek

End Function

Usage Example-1:

Calling AccWeek() Function from a Query Column:

SaleWeek:AccWeek([SaleDate])

Usage Example-2:

Use it in a Text Box on a Form or Report:

=AccWeek([SaleDate])

Usage Example-3:

Call from within your own Code:

intSaleWeek = AccWeek(dtSaleDate)

Note: AccWeek() Function is not extensively tested in field conditions and may be used at your own risk. If you find any logical errors in the code, please share them with me too.

Technorati Tags:

Earlier Post Link References:

Powered by Blogger.