Streamlining Form Module Code in Standalone Class Module.
Ready-made Class Modules for Data-Entry, Editing, or Viewing.
All the TextBox and ComboBox Controls, on the data handling Form, when enabled with the Dirty(), and BeforeUpdate() Event Procedures are fully protected from unintentional changes.
Manually writing code for every TextBox and ComboBox on a form can lead to duplication of work and inefficiency. Moreover, modifying event procedure names for each field to match the control name can become tedious and error-prone. Typically, only essential fields undergo this kind of data protection exercise, leaving others vulnerable.
To streamline this process, consider implementing a more automated or systematic approach, such as leveraging reusable code structures, like Standalone Class Modules, that help to centralize and organize Event Procedures more efficiently.
Utilizing a Class Module with VBA Coding enables a swift and automated solution to implement data protection methods across all fields on the form. By leveraging Events Dirty() and BeforeUpdate() Subroutine Code reuse techniques, these data-protecting procedures can be efficiently applied to all TextBoxes and ComboBoxes on the form. This streamlined approach ensures quick and consistent implementation of data protection measures, enhancing the overall robustness and security of the form's data handling processes.
With the following few Simple Steps let us do a Demo Run to understand how it works:
- Use the Form-Wizard to create a Form: Columnar or Tabular Design using any Table/Query as a data source.
Open the Form in Design View.
- Display the Form Property Sheet and Select the Other Tab.
Change the Has Module Property Value to Yes.
- Display the Form Module.
Copy and Paste the following VBA Code into the Form Module.
Option Compare Database Option Explicit Private Cls As New Class_ObjInit Private Sub Form_Load() Set Cls.o_Frm = Me End Sub Private Sub Form_Unload(Cancel As Integer) Set Cls = Nothing End Sub
Sample Form Image with the Employees Table.
Save your Form, but do not open it at this time. We need to create the Class Modules first.
There are three ready-made Class Modules, with a single prewritten OnDirty() and BeforeUpdate() Event Procedures. When the Form is open the Class_ObjInit Class Module is Instantiated in the global declaration area with the object name Cls and in the Form_Load() Event Procedure the Cls.o_Frm Property of the Class Module is assigned with the current Form Object Me.
When the Class_ObjInit Class Object is Instantiated the Data_TxtBox Class and the Data_CboBox Classes declared in the Class_ObjInit Class are also loaded into memory. We will create these Class Modules with the Event Subroutine Codes next.
Open the VBA Editing Window (ALT+F11)
- Create a Class Module, Click on the Properties Window Icon (the icon between Project Explorer and Object Browser Icons) to display the Property Sheet of the Module. Change the Module Name from Class1 to Class_ObjInit.
Copy the VBA Code given below Paste them into the Class_ObjInit Class Module and Save them.
The Class_ObjInit Class Module.
Option Compare Database Option Explicit Private txt As Data_TxtBox Private Cbo As Data_CboBox Private Coll As New Collection Private frm As Form Private DetSec As Section '------------------------------------------------------ 'Streamlining Form Module Code 'in Stand-alone Class Modules 'With Reusable Code '------------------------------------------------------ 'Quick Data Entry Screen 'Saving Table/Query Records in Collection Object 'Author: a.p.r. pillai 'Date : 10/05/2024 'Remarks: with Ready-made Data Entry Events Handler ' : in the Wrapper TextBox Class Module ' : Suitable for Columnar, Tabular or DataSheet Form 'Rights: All Rights(c) Reserved by www.msaccesstips.com '------------------------------------------------------ Public Property Get o_Frm() As Form Set o_Frm = frm End Property Public Property Set o_Frm(ByRef vFrm As Form) Set frm = vFrm Class_Init End Property Private Sub Class_Init() Dim fldNames() As String Dim j As Long Dim Path As String Dim ctl As Control On Error GoTo ClassInit_Err Set DetSec = frm.Section(acDetail) Const EP = "[Event Procedure]" 'Save Form Detail Section Field Names 'to this Text File for creating Event Subroutine Template Path = CurrentProject.Path & "\EventSubFields.txt" If Len(Dir(Path)) > 0 Then Kill Path End If Open Path For Output As #1 'Instantiate the 'Data_txtBox' Class for each TextBox 'on the Form for streamlined Event Procedures Coding j = 0 For Each ctl In DetSec.Controls Select Case TypeName(ctl) Case "TextBox" j = j + 1 ReDim Preserve fldNames(1 To j) As String fldNames(j) = ctl.Name Set txt = New Data_TxtBox Set txt.m_Frm = frm Set txt.m_txt = ctl '//Colin Riddington Technique: Highlighting BackColor on GotFocus txt.m_txt.BackColor = 62207 'RGB(&HFF, &HF2, &H0):Yellow Background txt.m_txt.BackStyle = 0 'Transparent Print #1, ctl.Name 'write Field Name in EventSubFields.txt File txt.m_txt.BeforeUpdate = EP txt.m_txt.OnDirty = EP Coll.Add txt 'Add Data_TxtBox Class Instance to Collection Set txt = Nothing 'Reset txt object Case "ComboBox" Set Cbo = New Data_CboBox Set Cbo.m_Frm = frm Set Cbo.m_Cbo = ctl '//Colin Riddington Technique: Highlighting BackColor on GotFocus Cbo.m_Cbo.BackColor = 62207 'RGB(&HFF, &HF2, &H0) Cbo.m_Cbo.BackStyle = 0 Cbo.m_Cbo.BeforeUpdate = EP Cbo.m_Cbo.OnDirty = EP Coll.Add Cbo Set Cbo = Nothing End Select Next Close #1 'Close Text File ClassInit_Exit: Exit Sub ClassInit_Err: MsgBox Err & ": " & Err.Description, , "Class_Init()" Resume ClassInit_Exit End Sub
We instantiate the Class_ObjInit Class Module in the Form Module and assign the Form object to its Property o_Frm. After receiving the Form Object in the Set Property Procedure the Class_Init() Subroutine is called.
The Red colored code lines in this Module will create a Text File EventSubFields.txt to save the Data Field Names from the Detail-Section of the Form. The purpose of this Field List will be explained later on.
The Data_TxtBox Class is Instantiated for each TextBox Control, the Data_CboBox Class (we will create both these Class Modules next) is Instantiated for each ComboBox Control on the Form, The Dirty() and BeforeUpdate() Events are enabled by setting the text "[Event Procedure]" in their OnDirty and BeforeUpdate Event Properties.
NB: If you have not gone through this topic's earlier Pages then you may find most of the discussion on this page somewhat strange. You will find this topic's earlier page Links at the end of this Page. You may visit those Pages, starting from the first one onwards. It starts with the Basics of this Coding concept of Form Module Event Subroutine coding in the Standalone Class Module. The Class_ObjInit Class Module's Code and its usage are almost the same in all the earlier examples too.
The BackColor Property is set with Yellow color and the BackStyle Property is set to Transparent so that the TextBox/ComboBox background highlights only when the Focus is on the Control.
After these changes the TextBox or ComboBox Wrapper Class Module Instance is added as a Collection Object Item, to keep them active in memory. When the Events are fired from the Controls on the Form they are trapped in the TextBox Instance in Collection Object and Execute the Event Subroutine Code.Remember, each TextBox on the Form has a Data_TxtBox Class Instance created, assigned with the TextBox Reference from the Form, and inserted into the Collection Object Item. When the Dirty() or BeforeUpdate() Event fires from that particular TextBox it is captured in the Data_TxtBox Class Instance representing that TextBox to execute the Event Subroutines.
This is the new VBA Event Subroutine Coding approach that I have designed for ease of VBA Coding in Standalone Class Modules instead of in Form/Report Module. This Coding approach has the following advantages:
- Reuse the Event Procedure Code without manual duplication of Event Procedures
Need only one structured Event Subroutine per Event (say BeforeUpdate()) for all Controls of the same Type (for all TextBoxes on the Form) and all the Event Procedure Codes are organized within a single Event Subroutine.
- Direct access to the Event Subroutines without interfering with the Form/Report Design
It eliminates the need for interacting with the Form/Report Design View for Code maintenance every time, resulting in faster Project completion.
Create another Class Module and change its name to Data_TxtBox. Copy the following VBA Code Paste it into the Data_TxtBox Class Module and Save it:
The Data_txtBox TextBox Class Module Code.
Option Compare Database Option Explicit Private WithEvents mtxt As TextBox Private mfrm As Form Dim msgtxt As String Const cr = vbCr '------------------------------------------------------ 'Streamlining Form Module Code 'in Stand-alone Class Modules 'With Reusable Code '------------------------------------------------------ 'Quick Data Entry Screen 'Author: a.p.r. pillai 'Date : 10/05/2024 'Remarks: with Ready-made Data Entry Events Handlers ' : in the Wrapper TextBox Class Module ' : Suitable for Columnar, Tabular or DataSheet Form ' : made for Table/Query. 'Rights: All Rights(c) Reserved by www.msaccesstips.com '------------------------------------------------------ Public Property Get m_Frm() As Form Set m_Frm = mfrm End Property Public Property Set m_Frm(ByRef vmFrm As Form) Set mfrm = vmFrm End Property Public Property Get m_txt() As TextBox Set m_txt = mtxt End Property Public Property Set m_txt(ByRef vmtxt As TextBox) Set mtxt = vmtxt End Property Private Sub mtxt_Dirty(Cancel As Integer) 'Global area of Subroutine 'If new Record Data Entry then ignore Dirty Event If mfrm.NewRecord Then Exit Sub End If 'VBA Code Runs for all Fields in the Detail Section msgtxt = "Editing Field [" & UCase(mtxt.Name) & "]?: " _ & mtxt.Value & cr & cr & "Allow the Change?" If MsgBox(msgtxt, vbYesNo + vbQuestion, _ mtxt.Name & "_BeforeUpdate()") = vbNo Then Cancel = True mtxt.Undo End If 'Field Specific Code for validation checks '---------------------------------------------- 'If Field Specific Event handling is required 'then make a Copy of the Data_TxtBox Class with 'a New Name and use with Fieldname based Event Procedure. '---------------------------------------------- Select Case mtxt.Name Case "ID" ' Code Case "Company" ' Code Case "Last Name" ' Code Case "First Name" ' Code End Select End Sub Private Sub mtxt_BeforeUpdate(Cancel As Integer) 'Global area of Subroutine 'VBA Code Runs for all Fields in the Detail Section 'If new Record Data Entry then ignore BeforeUpdate Event If mfrm.NewRecord Then Exit Sub End If msgtxt = mtxt.Name & " Old Value: " & mtxt.OldValue & _ cr & cr & "Update to ?: " & mtxt.Value If MsgBox(msgtxt, vbYesNo + vbQuestion, mtxt.Name & "_BeforeUpdate()") = vbNo Then Cancel = True mtxt.Undo End If '---------------------------------------------- 'If Field Specific Event handling is required 'then make a Copy of the Data_TxtBox Class with 'a New Name and use it. '---------------------------------------------- 'Copy and Paste Cls_EventSub_Template Code here Select Case mtxt.Name 'Replace with Case "ID" ' Code Case "Company" ' Code Case "Last Name" ' Code Case "First Name" ' Code End Select End Sub
The TextBox Class has the mtxt_Dirty() Event Procedure that monitors the active TextBox for data change attempts by the user. When a key press is detected in a Field a message will appear asking whether the user wants to change the data. If the response is positive then allows to make changes to the field.
When the changed data is about to save the mtxt_BeforeUpdate() Event fires, and at this point, the system asks to reconfirm updating the new changes. If the response is negative then the changes are reversed and the original value is restored.The Dirty() and BeforeUpdate() Event Subroutines protect the data of all the Fields/TextBoxes in the Form's Detail Section.
Within the Select Case . . . End Select structure some Field Names from the Employees Form is shown below. If we need to write VBA Code with specific requirements for Field(s) then we need to write them in this Structure under each Field Name. We will discuss this aspect and what to do in those circumstances a little later. Here it is presented for information purposes only.
Create another Class Module with the Name Data_CboBox for the ComboBox Controls on the Form. Copy the following VBA Code Paste it into the Data_CboBox Class Module and save the Module.
The Data_CboBox ComboBox Class Module Code.
Option Compare Database Option Explicit Private WithEvents mCbo As ComboBox Private mfrm As Form Dim msgtxt As String Const cr = vbCr '------------------------------------------------------ 'Streamlining Form Module Code 'in Stand-alone Class Modules 'With Reusable Code '------------------------------------------------------ 'Quick Data Entry Screen 'Author: a.p.r. pillai 'Date : 10/05/2024 'Remarks: with Ready-made Data Entry Events Handler ' : in the Wrapper TextBox Class Module ' : Suitable for Columnar, Tabular or DataSheet Form ' : made for Table/Query. 'Rights: All Rights(c) Reserved by www.msaccesstips.com '------------------------------------------------------ Public Property Get m_Frm() As Form Set m_Frm = mfrm End Property Public Property Set m_Frm(ByRef vmFrm As Form) Set mfrm = vmFrm End Property Public Property Get m_Cbo() As ComboBox Set m_Cbo = mCbo End Property Public Property Set m_Cbo(ByRef vmCbo As ComboBox) Set mCbo = vmCbo End Property Private Sub mCbo_Dirty(Cancel As Integer) 'Global area of Subroutine 'If new Record Data Entry then ignore Dirty Event If mfrm.NewRecord Then Exit Sub End If 'VBA Code Runs for all Fields in the Detail Section msgtxt = "Editing ComboBox [" & UCase(mCbo.Name) & "]?: " _ & mCbo.Value & cr & cr & "Allow the Change?" If MsgBox(msgtxt, vbYesNo + vbQuestion, mCbo.Name & "_BeforeUpdate()") = vbNo Then Cancel = True mCbo.Undo End If Select Case mCbo.Name Case "Combo1" 'Code Case "Combo2" 'Code End Select End Sub Private Sub mCbo_BeforeUpdate(Cancel As Integer) 'Global area of Subroutine 'VBA Code Runs for all Fields in the Detail Section 'If new Record Data Entry then ignore BeforeUpdate Event If mfrm.NewRecord Then Exit Sub End If msgtxt = mCbo.Name & " Old Value: " & mCbo.OldValue & _ cr & cr & "Update to ?: " & mCbo.Value If MsgBox(msgtxt, vbYesNo + vbQuestion, mCbo.Name & "_BeforeUpdate()") = vbNo Then Cancel = True mCbo.Undo End If Select Case mCbo.Name Case "Combo1" 'Code Case "Combo2" 'Code End Select End Sub
The ComboBox Event Procedure is the same as the TextBox Code.
The active Field background will be highlighted with the Yellow color when the Field receives the Focus.
Save all the Modules and Compile them from the VBA Window to ensure that everything is ok.Test Running the Form.
- Open the Form in Normal View.
Click on a Field and touch a Key to edit the Field. A message will appear asking you whether you would like to edit the field or not? The OnDirty Event is enabled in all the TextBoxes and Comboboxes to protect the data from unintentional changes.
If your response is Yes then you are allowed to edit the Field. Type one or two characters at the end of the existing text in the Field then press Enter Key.
While saving the changes the BeforeUpdate() Event will fire and a message will appear again asking you to reconfirm the update action. If your response is negative then changes are reversed to the original value.
Data Entry, Editing, and Viewing.
The Class Modules are designed to work with any Form created for Data Entry, Editing, or Data View purposes.
- The Form can be created using the Form Wizard or manually in Columnar, Tabular, or DataSheet Design using Table or Query as Source. The Fields on the Form can be picked selectively or all from the Source Table or Query.
After creating a Form, copy the VBA Code from the Form1 Module Paste it into the new Form Module, save the Form, and open it in normal view.
With the above two steps your Form is ready with all the supporting Programs and the data is fully protected from changes. How much time it takes to do the above two steps?
The Program will monitor the Fields in TextBoxes and ComboBoxes (if present) on the Form.
The Dirty() and BeforeUpdate() Event Procedure Code are applied to all the TextBoxes and ComboBoxes (if present) on the Form.
When the Form is in Data Entry Mode (for a new Record) the OnDirty() and BeforeUpdate() Events are disabled.
Data Validation Checks.
The validation requirements of each Field are different. The Validation checks can be performed in two different ways.
1. Through the Validation Rule and Validation Text Properties (recommended) of the Table or through these Properties of the TextBoxes in the Form.
2. Through VBA Code using Event Procedures.
In this Project, the recommended procedure is the first option to use the Validation Rule and Validation Text Properties of the Field in Table Design View, or in the same Properties of the TextBox Field on the Form. If it is already written in the Table Field Properties then not required to repeat it in the Form Field.
Assign an Error Message in the Validation Text Property to display the message when the entered data is invalid. For example, the Date of Birth entered into the Date Field is invalid if it is greater than Today and the message Text can be 'Future Date Invalid'.
The Validation Rule Property accepts simple expressions to evaluate the entered data.
Example: The Last Name Field length is 15 characters or less and the validation expression is:
Validation Rule: Is Null OR Len([Last Name]) <= 15
Validation Text: Last Name maximum 15 characters only.
The Validation Text message will appear when the Last Name is longer than 15 characters.
If some of the Data Fields require validation checks then the above Properties (either in the Table Field OR the TextBox on the Form, but not necessary in both places) can be assigned with appropriate expressions and messages. Check Allen Browne's Microsoft Access Tips Page for more information on writing the Validation Check expressions.
If the requirement is complex and needs VBA to handle the data validation checks then you may make copies of the above three Class Modules and rename them suitably to identify them with the Form and write VBA Event Procedures under the Field Names, as we did in the earlier Tutorial examples.
When VBA Event Procedures are written with Field/TextBox names then those Class Modules cannot be used for any other Form without change. In such cases follow the above procedure.
For example: With Customized VBA Code for the Employees Form.
- Emp_ObjInit
- Emp_TxtBox
- Emp_CboBox
Then change the Class Module Name declared in the global area of the Form Module and in the Emp_ObjInit Module as shown in the following examples:
The Form Module Code change is highlighted.
The Wrapper Class Declarations in the Emp_ObjInit Class Module.
Keeping this requirement in mind I devised a method to generate an Event Subroutine Template using the Data Field Names, saved from the TextBoxes on the Form, so that it can be copied for specific Event Subroutine and write the Code directly below the required Fields and remove the unwanted Field references from the Subroutines.
The Sample Subroutine Code generated from the Field Names collected from the Form and saved in the EventSubFields.txt File is given below for reference:
Private Sub txt_BeforeUpdate(Cancel As Integer) Select Case txt.Name Case "ID" ' Code Case "Company" ' Code Case "Last Name" ' Code Case "First Name" ' Code Case "E-mail Address" ' Code Case "Job Title" ' Code Case "Address" ' Code Case "City" ' Code Case "State/Province" ' Code Case "ZIP/Postal Code" ' Code Case "Country/Region" ' Code End Select End Sub
The above BeforeUpdate() Event Procedure Code Template is generated through the following procedure:
When the Form is open the Class_ObjInit Class Module Class_Init() Subroutine collects the Field Names from the TextBoxes on the Form and saves them into the EventSubFields.txt File in the Database's Folder. See the red colored lines of Code in the Class_Init() Subroutine.
Run the Public Function (in Module1): CreateEventTemplate from the Debug Window (Immediate Window). It will build the above Subroutine Template in the Class Module ClsEventSub_Template. The Field Names are picked from the EventSubFields.txt Text File created earlier.
Procedure to create the ClsEventSub_Template Class Module Code.
- Open the required Form for a few seconds then Close it.
Open the Immediate Window, type the function name CreateEventTemplate and press Enter Key.
- The ClsEventSub_Template Class Module will have the Event Subroutine Template with all the Fields collected from the Form.
Highlight the entire Code then copy and paste it into the TextBox Wrapper Class Module Emp_TxtBox and change the Event Subroutine Name, (if necessary to match the Object declaration and the Subroutine Name), and write the Event Subroutine Code under the Field Name.
The unwanted field names may be removed from the Copied Subroutine.
If you follow the above steps for another Form the ClsEventSub_Template will contain the Field Names from the latest Form opened.
Demo Database Download
- Reusing Form Module VBA Code for New Projects.
- Streamlining Form Module Code - Part Two.
- Streamlining Form Module Code - Part Three
- Streamlining Form Module Code - Part Four
- Streamlining Form Module Code - Part Five
- Streamlining Form Module Code - Part Six
- Streamlining Form Module Code - Part Seven
- Streamlining Form Module Code - Part Eight
- Streamlining Form Module Code - Part Nine
- Streamlining Form Module Code - Part Ten
- Streamlining Form Module Code - Part Elevan
- Streamlining Report Module Code in Class Module
- Streamlining Module Code Report Line Hiding-13.
- Streamlining Form Module Code Part-14.
- Streamlining Custom Made Form Wizard-15.
- Streamlining VBA Custom Made Report Wizard-16.
- Streamlining VBA External Files List in Hyperlinks-17
- Streamlining Events VBA 3D Text Wizard-18
- Streamlining Events VBA RGB Color Wizard-19
- Streamlining Events Numbers to Words-20
- Access Users Group(Europe) Presentation-21
- The Event Firing Mechanism of MS Access-22
- One TextBox and Three Wrapper Class Instances-23
- Streamlining Code Synchronized Floating Popup Form-24
- Streamlining Code Compacting/Repair Database-25
- Streamlining Code Remainder Popup Form-26
- Streamlining Code Editing Data in Zoom-in Control-27
- Streamlining Code Filter By Character and Sort-28
- Table Query Records in Collection Object-29
- Class for All Data Entry Editing Forms-30
- Wrapper Class Module Creation Wizard-31
- wrapper-class-template-wizard-v2
No comments:
Post a Comment
Comments subject to moderation before publishing.