Learn Microsoft Access Advanced Programming Techniques, Tips and Tricks.

Monday, November 28, 2011

VBA Module Object and Methods

Introduction.

The VBA Module Object has several interesting methods and properties.  Last week, we saw how to insert a Click Event Procedure in a Form Module with a Function. You can find this blog post here.

I don’t say that frm.Module.CreateEventProc()  The method, which we have tried, was an easy approach for writing a one-line statement in a Form Module.  But, trying something different is always exciting; programming is like exploring the unknown.  After all, it is there as part of the Application to explore and learn. 

Today, we will try an alternative and simple method for the same example we tried last week.  That is to write all the program lines in a text file and load that program directly into the Form Module.

If you have tried last week’s example, we can use the same ‘Sample’ Form for today’s trial run,  or do the following to get prepared:

Loading VBA Code from Text File.

  1. Open a new Form in Design View.

  2. Create a Command Button on the Detail Section of the Form.

  3. While the Command Button is in the selected state, display its Property Sheet (F4 or ALT+Enter).

  4. Change the Name Property Value to cmdRun and the Caption Property Value to Run Report.

  5. Save the Form with the name Sample.

  6. If you have last week’s Sample form, then open it in Design View.

  7. Display the Form Module, remove the existing program lines, and save the Form.

  8. Open Notepad, copy and paste the following program lines into Notepad, and save it as c:\windows\temp\vbaprg.txt

    Private Sub cmdRun_Click()
    
        DoCmd.OpenReport "myReport", acViewPreview
    
    End Sub
  9. Replace the report name "myReport" with one of your own Report Names from the database.

  10. Open a Standard VBA Module, copy and paste the following main program into the Standard Module:

    The LoadFromTextFile() Function.

    Public Function LoadFromTextFile()
    Dim frm As Form, frmName As String, ctrlName As String
    
    frmName = "Sample"
    'ctrlName = "cmdRun"
    
    'Open the form in design view
    DoCmd.OpenForm frmName, acDesign
    
    'define the form object
    Set frm = Forms(frmName)
    
    'call the form's Module Object's AddFromFile() method
    'to read the program from the text file
    'and insert them into the Form Module
    frm.Module.AddFromFile "c:\windows\temp\vbaprg.txt"
    
    'Save and close the form with the code
    DoCmd.Close acForm, frmName, acSaveYes
    
    'Open the form in Normal view
    DoCmd.OpenForm frmName, acNormal
    
    End Function
  11. Place the cursor in the middle of the Code and press F5 to run the Code.

  12. Press ALT+F11 to display the Database window with the Sample Form open.

  13. Click on the Command Button to open the Report in print preview.

  14. Close the Report.

  15. Change the Sample Form in Design View.

  16. Open the form module and check for the program lines we have loaded from the vbaprg.txt file.
Technorati Tags:

Earlier Post Link References:

Sunday, November 20, 2011

Writing VBA-Code with VBA

Introduction.

To insert an Event Procedure in a Form or Report, we will open the VBA Module and write the code manually.  If we open the Class Module through the Event Property on the Property Sheet of a Control or Form (after setting the “[Event Procedure]” value in the Event property), then the procedure’s opening and closing statements (see the example given below) will be inserted by Microsoft Access automatically. After that, we insert the necessary body lines of the procedure manually between those opening and closing statements.

Sample empty Subroutine stub of Form_Current() Event Procedure is shown below:

Private Sub Form_Current()

End Sub

Let us do it differently this time by programming a Command Button Click event procedure automatically through VBA. We are going to insert a Command Button Click Event Procedure in a Form Module with the help of a Function Write_Code().  We learned something similar through an earlier article on the topic: Creating an Animated Command Button with VBA

A sample Trial Run.

In this trick, the Command Button is programmed automatically to open a Report in Print Preview.  The following are the lines of VBA Code we are going to insert into the Form Module automatically:

Private Sub cmdRun_Click()

    DoCmd.OpenReport "myReport", acViewPreview

End Sub
  1. Open a new blank Form in Design View.

  2. Add a Command Button control on the Form.

  3. While the Command button is in the selected state, display its Property Sheet (F4 or ALT+Enter).

  4. Change the Name Property Value to cmdRun.

  5. Change the Caption Property Value to Run Report.

  6. Save and close the Form with the name frmSample.

  7. Open VBA Editing Window (ALT+F11) and insert a new Standard Module. You can toggle Database and Code Window with the ALT+F11 Keyboard shortcut.

  8. Copy and paste the following Code into the Standard Module and save it:

    Public Function Write_Code(ByVal frmName As String, ByVal CtrlName As String)
    Dim frm As Form, x, txt As String, ctrl As Control
    
    DoCmd.OpenForm frmName, acDesign, , , , acHidden
    Set frm = Forms(frmName)
    Set ctrl = frm.Controls(CtrlName)
    With ctrl
        If .OnClick = "" Then
           .OnClick = "[Event Procedure]"
        End If
    End With
    
    x = frm.Module.CreateEventProc("Click", ctrl.Name)
    
    txt = "DoCmd.OpenReport " & Chr$(34) & "myReport" & Chr$(34) & ", acViewPreview"
    frm.Module.InsertLines x + 1, txt
    
    DoCmd.Close acForm, frmName, acSaveYes
    DoCmd.OpenForm frmName, acNormal
    
    End Function
  9. Replace the Report name "myReport" with one of your own Report names in the program line: txt = "DoCmd.OpenReport " & Chr$(34) & "myReport" & Chr$(34) & ", acViewPreview".

  10. Display the Debug Window (Ctrl+G).

  11. Type the following line in the Debug Window and press Enter Key:

    Write_Code "frmSample","cmdRun"

    The Form’s name "frmSample"  is passed as the first parameter to the Write_Code() Function, and the Command Button’s name "cmdRun" is passed as the second parameter.

  12. Press ALT+F11 to display the Database window.  You can see that frmSample is already open in normal view after inserting the program lines in its Code Module.

  13. Click on the Command Button to open your Report in Print Preview with the cmdRun_Click() Event Procedure.  You may change the Form View into Design View, open the Form Module, and check the lines of Code we have inserted in there.

At the beginning of the above program, the OnClick Event Property is checked for the presence of any programmed action, like a Macro Name, and if found empty, then it inserts the text "[Event Procedure]" in the property in preparation for writing the program lines in the VBA Module.

In the next step, the Form Module’s CreateEventProc() method is called to create the Click Event Procedure of the Command Button: cmdRun.  If you want a Double-Click Event procedure, rather than a Click() event procedure, then change the word "Click" to "dblClick".

Replace the 'DoCmd.OpenReport' statement with appropriate Code for other actions like MouseMove.

You can call the Write_Code() function from a Command Button and click Event Procedure on a Form.  Create two TextBoxes on the Form, enter the Form Name and Control Names in them respectively, and use the text box names in both parameters of the Write_Code() function.

Earlier Post Link References:

Friday, November 11, 2011

Control SetFocus on Tab Page Click

Introduction

A question was raised in an MS Access Discussion Forum:

"When I click on a Tab Control Page, I want to set focus on a particular Text Box on that page, not on the first Text Box by default. How can I do this?"

The user attempted a solution by writing code in the Page2_Click() event procedure of the Tab Control. Specifically, they tried variations of the following lines to set focus on the "Ship City" text box located on that page:

Private Sub Page2_Click()
     Forms!frm_Main![Ship City].SetFocus 
     frm_MainMenu![Ship City].SetFocus 
     me.[Ship City].SetFocus 
End Sub 

Tab Control-based Menus.

The Tab Control is an interesting and versatile object to use on a form. Personally, I have often used it to build form-based menus, placing list boxes on its pages to organize navigation options. For example, the image below shows a sample control screen with list box–based menus arranged neatly on the tab pages.

The middle of the Control Form shows a list as a menu of choices.  In fact, there are fifteen different sets of menus displayed there.  They are displayed one over the other by clicking on a set of Command Buttons, shown on either side of the list box.  You can learn this trick here.

Use Change Event for Click Event.

Coming back to the topic, the first thing that you should know is that when you click on the Tab-Page Button (see the sample image below) on a Tab-Control, the Click Event procedure will not be fired; instead, it fires the Change() Event. So use the Change() Event for Tab Page Clicks.

The Click event of a Tab Control fires only when you click on the top border area to the right of the tab pages. This means you need two clicks: one to select the tab-page button (to display its contents), and another on the Tab Control’s border to trigger the event procedure. Clearly, this is not a convenient approach. Instead, we will take an alternative route that allows the task to be completed with a single click, using a different method.

If you have already explored the text links provided earlier, you may have picked up a few ideas—and are probably one step ahead of what I am about to explain here.

Single Click Solution.

The simple method is using the Change Event Procedure on the TabPage Click.

We will implement the following ideas for a different approach:

  1. Create a separate Command Button for each Tab-Page, with one line of VBA code to make it current or visible.

  2. In the Command Button Click Event Procedure, we will add one more line of code to move the focus to a particular text box in the middle of the tab page.

  3. Since we have Command Buttons to display Tab Pages, we will hide the Tab-Page Buttons of the Tab-control. Optionally, change the Tab-control’s back-style design to transparent to make the tab control’s border design invisible.

Skipping the Fancy Work.

Before diving into the detailed design of the steps mentioned earlier, let me share a very simple solution—if you’re not interested in all the extra work. Simply set the Tab Index property of the text box (for example, [Ship City]) to 0.

Be careful not to confuse the Tab Index with the Tab Control or Tab Page. The Tab Index property determines the order in which the cursor moves from one control (such as a text box, combo box, or check box) to the next when you press the Tab key on the keyboard.

These values are assigned sequentially, starting from 0 up to the number of controls that have a Tab Index property on the form. Access sets these values automatically, based on the order in which you add controls to the form—either manually or through the Form Wizard. When the form opens, the control with Tab Index = 0 receives the focus by default, regardless of where it is physically placed on the form.

So, if the [Ship City] Field is not the starting point on your form and you want to make it, then do the following:

  1. Open the form in design view.

  2. Click on the [Ship City] field to select it.

  3. Display its Property Sheet (F4 or ALT+Enter).

  4. Find the Tab Index Property and change the Value to 0.  Other controls’ Tab Index Property values will be automatically changed by Access.  You must review and change them, if needed, to bring them into the desired order.

NB:  Each Tab Page is like a separate sub-form and has a separate set of Tab Index sequence numbers starting with zero on it, even if you place a different group of fields from the current record.

Showing your Professionalism.

Now that you already know the quick and easy solution, let’s explore some advanced tricks for working with Tab Control programming.

Building a database to store and retrieve data is relatively simple—almost anyone can put one together using whatever method they find easiest. That might be fine for personal use, but when presenting a database to a client or end user, appearance and usability matter a great deal. A well-designed interface not only improves user experience but also reflects your professionalism and attention to detail.

Returning to our topic, let’s take a closer look at the first three steps of the alternative approach we outlined earlier. For this demonstration, we’ll design a sample form with a Tab Control containing three pages, each holding different groups of information from the Orders table in the Northwind sample database. You can use any table of your choice to create a similar form. On the left side of the Tab Control, add three command buttons to support our trial run.

The Design Task

  1. Click on the first Command Button to select it.

    • Display its Property Sheet (F4 or ALT+Enter keys).

    • Change the Name Property Value to cmdOrder and the Caption Property Value to Order Details.

    • Click on the Event Tab of the Property  Sheet, select On Click Event property, and select [Event Procedure] from the drop-down control.

    • Click on the Build ( . . . ) Button to open the Form’s VBA Module with an empty sub-routine stub.

    • Copy and paste the following lines of Code, overwriting the existing lines, or simply copy the middle line alone and paste it between the sub-routine opening and closing lines, as shown below.

      Private Sub cmdOrder_Click()
        Me.TabCtl0.Pages(0).SetFocus
      End Sub
  2. Similarly, change the middle Command Button’s Name Property Value to cmdShipper and Caption Property Value to Shipper Details.

    • Follow the last three steps mentioned above to copy-paste the following code for the middle Command Button Click Event Procedure:
      Private Sub cmdShipper_Click()
        Me.TabCtl0.Pages(1).SetFocus
        Me.Ship_City.SetFocus
      End Sub

      In the first line of code, we changed the Tab page reference from Page(0) to Page(1), which points to the second page of the Tab Control. We then added one more line:

      Me.Ship_City.SetFocus

      This moves the insertion point directly to the Ship City field, regardless of its physical placement on the form. As a result, a single click on the command button not only switches to the second tab page but also sets the focus on the Ship City field.

      Notice that we are addressing the control (Me.Ship_City.SetFocus) as though it were placed directly on the form surface, rather than treating it as a child control of the Tab Page. Keep in mind that each group of fields on a Tab Page has its own Tab Index sequence, starting from 0, which determines how the cursor moves among controls on that page.

      If you prefer, you can also reference the control explicitly as a child of the Tab Page, like this:

      Me.TabCtl0.Pages(1).Controls("Ship City").SetFocus

      This approach is equally valid.

  3. Change the last Command Button’s Name Property Value to cmdPayment and Caption Property Value Payment Details.

    • Copy-paste the following lines of code for the last Command Button Click Event Procedure, as you did in the earlier two cases:
      Private Sub cmdPayment_Click()
         Me.TabCtl0.Pages(2).SetFocus
      End Sub
  4. Save the Form and open it in the normal view. When you open the form, by default, Page1  of the tab control will be active.

  5. Click on the middle Command Button. You can see the second page of the Tab Control become active, and the control "Ship City" field is in focus now.

  6. Click on the Payment Details Command Button to select the third page. You may try all the command buttons repeatedly to get the feel of their usage.

    Since our command buttons took over the function of Tab-Pages of the Tab Control Object, we don't need the Tab Control Page buttons above, and we will remove them.

  7. Change the Form Mode in Design View.

  8. Click on the Tab Control by clicking on the right side of the Page3 button.

  9. Display the Property Sheet (F4).

  10. Click on the All tab of the property sheet and set the Style Property Value to None from the drop-down list.

The Demo Run.

If you open the form in Normal View, the Tab Control will appear as shown in the image below, without the tab page indicators. Clicking the command buttons will still switch the pages, just as before.

You can take this a step further by “hiding” the Tab Control’s identity marks entirely. To do this, set the

Back Style property of the Tab Control to Transparent. This creates a clean, seamless interface while retaining full tab functionality—a simple but impressive “magic trick.”

  1. Change the form to design view (if the form is in normal view) and change the Back Style Property Value to Transparent.

  2. Save the Form and open it in Normal View.

    No sign of the Tab Control now, except for displaying the controls on the first Tab Page with their values and labels. Click on the Command Buttons one after the other. You will find that the data fields and their labels appear from nowhere, occupying the same area every time, like magic.

Powered by Blogger.