Learn Microsoft Access Advanced Programming Techniques, Tips and Tricks.

WithEvents in Class Module and Data Entry Form

1. Introduction.

So far we have used Unbound Text Boxes on Form for Demo runs, and for built-in Event capturing in Class Module Object.  Since, Text Boxes are the main control used on Forms, for data entry/display/view of information, it was the first preferred choice for demonstration of the most frequently used built-in Events: AfterUpdate, OnGotFocus, and OnLostFocus.

That doesn’t mean that we have ignored Command Buttons, Combo Boxes, List Boxes, and others.   All these controls mostly use the Click Event, to open Form/Report or run macros/subroutines/functions,  select an item from  Combo box or List Box or Option Button and they are much easier to handle in their Event Procedures in the Class Module.  We will take those controls also along with TextBoxes

Once you are familiar with handling the Text Box-based Events alone and understand how it works, the other controls will be a simple addition to the whole scheme of things.

Adding Class Module Object instance, one instance for each Text Box on the Form, into the Array element, enabled with required built-in Events itself is somewhat confusing, but not complicated.

If you have not touched on the topic of programming the stand-alone Class Module I suggest you better start from there.  It will help you a lot and much easier to understand its usage in WithEvents, Event, and RaiseEvent programming.  Go through the following Articles, to get a general idea of Class Module Programming.

  1. MS-Access Class Module and VBA
  2. MS-Access VBA Class Object Arrays
  3. MS-Access Base Class and Derived Objects
  4. VBA Base Class and Derived Object-2
  5. Base Class and Derived Object Variants
  6. MS-Access Recordset and Class Module
  7. Access Class Module and Wrapper Classes
  8. Wrapper Class Functionality Transformation

2. Brief Review of what is covered so far.

In the last few weeks, we have started with the topic of Class Module and Form Controls Event Programming with Microsoft Access and learned how to create a Class Module Object Array element for each Text Box on Form.

The preparations for creating a Class Module for Text Box object are something like the following steps.

  1. Creates a Class Module with the Text Box (Access.TextBox) Property with Object (or Variable) name like txt.
  2. If the Property is declared as Private then Get/Set Property Procedures are added to manage the txt Object.
  3. Event Handling sub-routines for AfterUpdate, GotFocus, and LostFocus are created in the Class Module.

When an instance of the above Class Module is created in memory it can handle only a single Text Box’s Event (AfterUpdate, GotFocus, and LostFocus) on the Form.

If there are more Text Boxes, say three TextBoxes, on the Form then we must create three instances of the same Class Module, one for each Text Box on the Form. 

To keep track of all the three instances of the Class Module they should be organized in an Array or add them as Collection Object Items, one after the other.

When the same Class Module instance is used for more than one Text Box the Event Procedures (sub-routines) need changes in the Class Module.  We must identify the Text Box that Raised the built-in Event on the Form.  Based on that information run the validation checks or any other action on that particular Text Box within the same sub-routine.

Example: The Code given below is taken from the AfterUpdate() Event Procedure. The FirstName and Designation TextBox’s AfterUpdate Event doesn't have any executable Code under them, in the Select Case . . . End Select structure, indicating that these TextBoxes exist on the Form but the AfterUpdate Event is not enabled or used for them.  If there is no executable code in them it is not necessary to add the Text Box name there.  But, adding those fields as part of the testing sequence reminds us of their presence on the Form.

But these TextBoxes may be enabled with any other Event like OnLostFocus and handled in the LostFocus Event Procedure.

txtName = Txts.Name

Select Case txtName
    Case "LastName" 'TextBox Name
        txtval = Trim(Nz(Txts.Value, ""))

        If Len(txtval) > 15 Then
           msg = "LastName Max 15 chars only."
           MsgBox msg, vbInformation, txtName & "_AfterUpdate()"
           Txts.Value = Left(Nz(txtval, ""), 15)
        End If
    Case "FirstName"
        '
    Case "Designation"
        '
    Case "BirthDate"
         db = CDate(Nz(Txts.Value, 0))
        
         If db > Date Then
           msg = "Future Date: " & db & " Invalid."
           MsgBox msg, vbInformation, txtName & "_AfterUpdate()"
           Txts.Value = Null
           efrm!Age = Null

         ElseIf db > 0 Then
           dbage = Int((Date - db) / 365)
           efrm!Age = dbage
         End If
    Case "Age"
         Dim xage As Integer
         db = CDate(Nz(efrm!BirthDate, 0))
         xage = Nz(Txts.Value, 0)
         
         If (db > 0) And (xage > 0) Then
            dbage = Int((Date - db) / 365)
            If xage <> dbage Then
                msg = "Correct Age as per DB = " & dbage
                MsgBox msg, vbInformation, txtName & "_AfterUpdate()"
                Txts.Value = dbage
            End If
         ElseIf (xage = 0) And (db > 0) Then
            dbage = Int((Date - db) / 365)
            Txts.Value = dbage
         End If
    Case "JoinDate"
       Dim jd As Date
       
       db = CDate(Nz(efrm!BirthDate, 0))
       jd = CDate(Nz(Txts.Value, 0))
       
       If (db > 0) And (jd < db) Then
          msg = "JoinDate < Birth Date Invalid!"
          MsgBox msg, vbInformation, txtName & "_AfterUpdate()"
          Txts.Value = Null
       End If
End Select

Note: If you need a Read/Write value from/to some other Text Box, other than the Event trapped Text Box, then you need Access.Form Property also in the Text Box Class Module: ClsTxtEmployees, to reference the other Text Box to read/write values.

This Class Module can be a Template for Other Form’s TextBoxes and subroutine customization is required depending on that particular Form's TextBox control's requirement.

The links to all the earlier Articles on this topic are given below if you are new to the WithEvents, Events, and Raise Events usage in User-Defined Events or built-in Event Programming with Microsoft Access, for easy access to those articles.

  1. WithEvents Ms-Access Class Module Tutorial
  2. WithEvents and Defining Your Own Events
  3. withevents Button Combo List TextBox Tab
  4. Access Form Control Arrays and Event Capturing
  5. Access Form Control Arrays and Event-2
  6. Access Form Control Arrays and Event-3
  7. WithEvents in Class Module for Sub-Form TextBox Events

3. What is New in this Post?

Here, we have a sample Employee Data Entry Form bound to a Table.  If you have gone through the earlier examples with TextBoxes on unbound Form you will not find any difference in this Demo.  The only idea here is to demonstrate the normal usage of Event handling in Class Module Object with the form bound to a table and the data fields as a control source to the TextBox.

The sample image of the Data Entry Form is given below.  An error message shown on the image is popped up (this is manually moved to the bottom right corner) when an invalid Join Date (less than birth date) is entered into the field.

The Command Button Click on the form is handled normally on the Form Module itself in the first Employee Form Demo.

In the Employee Form demo the Form’s Class Module and a Class Module with two Private Properties, Txts for Text Box Object, and efrm for Access.Form Objects are used.

4.  New Class Module Code.

Insert a new Class Module and change its Name Property value from Class1 to ClsTextEmployees.

Copy and Paste the following VBA Code into the Class Module and save the Code:

Option Compare Database
Option Explicit

Private efrm As Access.Form
Private WithEvents Txts As Access.TextBox

Public Property Get pfrm() As Access.Form
  Set pfrm = efrm
End Property

Public Property Set pfrm(ByRef vNewValue As Access.Form)
  Set efrm = vNewValue
End Property

Public Property Get pTxts() As Access.TextBox
  Set pTxts = Txts
End Property

Public Property Set pTxts(ByRef vNewValue As Access.TextBox)
  Set Txts = vNewValue
End Property

Private Sub Txts_AfterUpdate()
Dim txtName As String, txt As String
Dim msg As String, txtval As Variant
Dim db As Date, dbage As Integer

txtName = Txts.Name

Select Case txtName
    Case "LastName"
        txtval = Trim(Nz(Txts.Value, ""))

        If Len(txtval) > 15 Then
           msg = "LastName Max 15 chars only."
           MsgBox msg, vbInformation, txtName & "_AfterUpdate()"
           Txts.Value = Left(Nz(txtval, ""), 15)
        End If
    Case "FirstName"
        '
    Case "Designation"
        '
    Case "BirthDate"
         db = CDate(Nz(Txts.Value, 0))
        
         If db > Date Then
           msg = "Future Date: " & db & " Invalid."
           MsgBox msg, vbInformation, txtName & "_AfterUpdate()"
           Txts.Value = Null
           efrm!Age = Null

         ElseIf db > 0 Then
           dbage = Int((Date - db) / 365)
           efrm!Age = dbage
         End If
    Case "Age"
         Dim xage As Integer
         db = CDate(Nz(efrm!BirthDate, 0))
         xage = Nz(Txts.Value, 0)
         
         If (db > 0) And (xage > 0) Then
            dbage = Int((Date - db) / 365)
            If xage <> dbage Then
                msg = "Correct Age as per DB = " & dbage
                MsgBox msg, vbInformation, txtName & "_AfterUpdate()"
                Txts.Value = dbage
            End If
         ElseIf (xage = 0) And (db > 0) Then
            dbage = Int((Date - db) / 365)
            Txts.Value = dbage
         End If
    Case "JoinDate"
       Dim jd As Date
       
       db = CDate(Nz(efrm!BirthDate, 0))
       jd = CDate(Nz(Txts.Value, 0))
       
       If (db > 0) And (jd < db) Then
          msg = "JoinDate < Birth Date Invalid!"
          MsgBox msg, vbInformation, txtName & "_AfterUpdate()"
          Txts.Value = Null
       End If
End Select
End Sub

Private Sub Txts_LostFocus()
Dim txtName As String
Dim msg As String, txtval As Variant

txtName = Txts.Name
txtval = Trim(Nz(Txts.Value, ""))

Select Case txtName
    Case "LastName"
        '
    Case "FirstName"
        If Len(txtval) = 0 Then
           msg = "FirstName should not be Blank."
           MsgBox msg, vbInformation, txtName & "_LostFocus()"
           Txts.Value = "XXXXXXXXXX"
        End If
    Case "Designation"
        If Len(txtval) = 0 Then
           msg = "Designation Field is Empty."
           MsgBox msg, vbInformation, txtName & "_LostFocus()"
           Txts.Value = "XXXXXXXXXX"
        End If
    Case "BirthDate"
        '
    Case "Age"
        '
    Case "JoinDate"
        '
End Select

End Sub

5. Class Module Properties and Sub-Routines.

On the Global area of the module an Access.Form Property efrm declared as Private Property.

Next, an Access.TextBox control is declared, with WithEvents keyword and object name Txts as Private PropertyThe WithEvents keyword enables the Txts Object to capture the programmed Events when triggered on the Form. 

When Class Module Properties are declared as Private, it is accessible only within the Class Module, preventing direct access to the Objects from outside, there must be Get/Set Property Procedures with Public Scope in the Class Module to assign/retrieve values to/from it.

The first Get/Set Property Procedure pairs are for the efrm Access.Form Object.

The next set of Get/Set Property Procedure pairs retrieves/assign TextBox Control in Txts Object.

Any validation checks on the Set Property Procedure parameter can be performed before attempting to assign the value to the Property efrm or Txts.

In the Class Module, we are handling only two types of built-in Events, AfterUpdate and LostFocus Events from TextBoxes on the Form.

The AfterUpdate() Event Procedures validates the Values of LastName, BirthDate, Age, and JoinDate Fields and displays an appropriate message, mainly to monitor whether the programmed Event is getting captured in the Class Module instance or not.

The LostFocus() Event Procedure validates the FirstName and Designation field values and assigns a default text String “XXXXXXXXXX” to the field if it is left empty during the Lost Focus Event.

All the Text Box names are listed in the Select Case . . . End Select structure for clarity, some without any executable code in it.  In the LostFocus Event Procedure, we have written code under the FirstName and Designation fields.  The lost Focus event is enabled on the Form only for these two data fields.  Other fields are included for clarity or for future use in case they are needed.

The first Text Box on the Form is an Auto-number field, that increments its contents automatically and we have no intention to trap any events on this particular control.  Hence, it is not at all taken in the Select Case . . . End Select structure, or enabled any Event on that control either.

6.  Employees Form Module Code.

The VBA Code behind the Employees Form's Class Module is given below:

Option Compare Database
Option Explicit

Dim tc As ClstxtEmployee
Dim C As Collection

Private Sub cmdClose_Click()
'Command Button Click Event is handled
'on the Form Module itself, the Event is
'not programmed in Class Module: ClsTxtEmployee
DoCmd.Close
End Sub

Private Sub Form_Load()
Dim ctl As Control

Set C = New Collection

For Each ctl In Me.Controls
  If TypeName(ctl) = "TextBox" Then
  
     Set tc = New ClstxtEmployee
     
     'Form Object is required to read/write values
     'from other TextbOX, if needed.
    Set tc.pfrm = Me
    'assign TextBox control to the Class Module instance's Property
    Set tc.pTxts = ctl
    
    Select Case ctl.Name
          Case "FirstName", "Designation"
          'enable LostFocus Event for FirstName and Designation
               tc.pTxts.OnLostFocus = "[Event Procedure]"
          Case Else
           'enable AfterUpdate for all other Text Boxes
               tc.pTxts.AfterUpdate = "[Event Procedure]"
    End Select
  End If
  C.Add tc 'add ClstxtEmployee instance as Collection Object Item
Next

End Sub

Private Sub Form_Unload(Cancel As Integer)
'when the form is closed erase Collection Object from memory
Set C = Nothing
End Sub

The Class Module ClsTxtEmployee is declared as tc Object.

A Collection Object is declared in Object C.

On the Form_Load() Event Procedure the Collection Object is instantiated.

Within the For Each . . Next loop the Employees Form Text Box controls are picked and enabled for the required built-in Events.

For each text box on the Form, Employee, a new instance of the Class Module ClsTxtEmployee is created and the Form Object and Text Control Property Values are passed to the Class Module Object.

7.  Derived Class Module to Replace Form Module Code.

As we did in the earlier cases we will create a Derived Class Object (ClsTxtEmployeeHeader), using ClsTxtEmployee Class as Base Class and transfer the above Form Module Code into the new Class Module and leave the Form's Class Module with the bare minimum of a few lines of code.

We will also transfer the Command Button Click Event handling into the Derived Class Module Object.

The Derived Class Module (ClsTxtEmployeeHeader) VBA Code is given below:

Option Compare Database
Option Explicit

Private tc As ClstxtEmployee
Private Col As New Collection

Private fm As Access.Form
Private WithEvents btn As Access.CommandButton


Public Property Get oFrm() As Access.Form
  Set oFrm = fm
End Property

Public Property Set oFrm(ByRef vNewValue As Access.Form)
  Set fm = vNewValue
  Call Class_Init
End Property

Private Sub Class_Init()
Dim ctl As Control

For Each ctl In fm.Controls
  Select Case TypeName(ctl)
  'If TypeName(ctl) = "TextBox" Then
    Case "TextBox"
        'create a new instance of Class Module Object
        Set tc = New ClstxtEmployee
        'assign common property values
        Set tc.pfrm = fm 'pass Form Employyes object to the new instance
        Set tc.pTxts = ctl  'pass text control
            
            'enable required event procedures for Text Boxes
            Select Case ctl.Name
                   'lostfocus event controls
                Case "FirstName", "Designation"
                    tc.pTxts.OnLostFocus = "[Event Procedure]"
                Case Else
                    'after Update Event
                    tc.pTxts.AfterUpdate = "[Event Procedure]"
            End Select
            Col.Add tc 'add to the collection object
    Case "CommandButton"
        Set btn = ctl
        btn.OnClick = "[Event Procedure]"
    End Select
Next

End Sub

Private Sub btn_Click()
   If MsgBox("Close the Form?", vbYesNo, btn.Name & "_Click()") = vbYes Then
    DoCmd.Close acForm, fm.Name
   End If
End Sub

In the above-derived Class Module, the first two object declarations for Text Box Class Module and Collection Object we have done on the Employees Form's Class Module are brought down to this new Class Module.

Next, an Access.Form object fm is declared to hold the Employees form object. This is required to read the date of birth (the BirthDate) Text Box and calculate the Age of the employee and update the value in the Age Text Box on the Form.

Next, a Command Button control Object is declared within the derived Class Module Object with the WithEvents keyword to take control of the Command Button click on the Form.

Once the Form Object reference is received in the Public Property Set oFrm() as a parameter and after assigning it to fm Object the Class_Init() Subroutine is called to run the Code to enable the AfterUpdate and LostFocus Event, earlier we run from the Form_Load() Event Procedure.

Now the only Code we run from the Form Class Module, on the Form_Load() Event Procedure, is to pass the reference of the current Form Object (Me) to the oFrm() Set Procedure in the derived Class Module Object ClsTxtemployeeHeader.  This Form reference is passed to the ClsTxtEmployee Class Module instance, through the statement  Set tc.pfrm = fm.

The Command Button Click Event Procedure is enabled and captured in the btn_Click() Event Procedure in the Derived Class Module ClsTxtEmployeeHeader itself.

8.  New Form using Derived Cass Module: ClsTxtemployeeHeader

The Image of the second sample form, after transferring all its Form Module Code into the Derived Class Module ClsTxtEmployeeHeader.

The EmployeeHeader (a copy of the Employees Form) Form's Class Module VBA Code is given below.

Option Compare Database
Option Explicit

Dim T As New ClsTxtEmployeeHeader

Private Sub Form_Load()
  Set T.oFrm = Me
End Sub

The Dim statement instantiates the derived object of ClsTxtEmployeeHeader in memory.

The Form_Load() Event Procedure passes the current form object to the class object T.oFrm() Property Procedure as a parameter.

9. Summary

The Derived Class Module holds the entire Form's Class Module Code, except for a few lines on the Form's Code Module.

The entire Code will be written, otherwise in the Form's Class Module, is kept away and safe in the Base Class Module ClsTxtEmployees and in the Derived Class Module ClsTxtEmployeeHeader. 

When you create another Form with features of similar nature, in this Project, or in your other Projects you can easily customize both the Class Modules.  This will keep things well organized and easy to implement form rather than writing fresh code on all Form's Class modules.

You may download the Demo Database attached at the end of this page with the sample Forms and Class Modules and try out them.

After going through them you may try something similar on your own, using the demo database as a reference point so that you can be sure of what you have learned so far.

Downloads.




Links to WithEvents ...Tutorials.

  1. WithEvents Ms-Access Class Module Tutorial
  2. WithEvents and Defining Your Own Events
  3. withevents Button Combo List TextBox Tab
  4. Access Form Control Arrays and Event Capturing
  5. Access Form Control Arrays and Event-2
  6. Access Form Control Arrays and Event-3
  7. WithEvents in Class Module for Sub-Form TextBox Events
  8. WithEvents in Class Module and Data Entry
  9. WithEvents and Access Report Event Sink
  10. WithEvents and Report Lines Hiding
  11. WithEvents and Report Lines Highlighting
  12. Withevents TextBox and Command Button Arrays
  13. Withevents TextBox CommandButton Dictionary
  14. Withevents and all Form Control Types
Share:

No comments:

Post a Comment

Comments subject to moderation before publishing.

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