Streamlining Form Module Code in Standalone Class Module.
Data Filter by Character and Sort on Form.
Version 1.0 of this Article was originally published in April 2009 and introduces a significant change in the Demo Application Version 2.0. In this version, the Event Subroutines are executed from the standalone class module, rather than from the form module.
After realizing the advantages of Event Procedures Coding in Standalone Class Modules, I found it difficult to revert to the traditional, less organized, and time-consuming Form/Report Module VBA Coding procedures.
In traditional coding, modifying the code of a specific event subroutine in a Form Module—especially when dealing with multiple types of controls—usually involves several manual steps.
- Open the Form in Design View.
Select the required Control.
- Display its Property Sheet.
Select the specific Event Property.
- Click on the Build Button to open the Event Procedure.
Write/Modify the Code.
- Save the Form with the Code.
Open the Form in Normal View to test the change.
Typically, it takes about eight steps to reach a specific event procedure in the Form Module to write, edit, and save changes. While it’s true that multiple event procedures can be modified once the form is open, steps 2 through 6 must still be repeated for each individual event procedure. This repetitive process is both tedious and time-consuming, especially when performed numerous times during development. At the same time, designing the user interface also consumes significant effort, as both activities often occur in parallel. Furthermore, any code written directly in the Form Module remains locked there and cannot be reused elsewhere, except for public functions written in a Standard Module.
If you’re a beginner VBA programmer, learning the language alongside user interface design is best accomplished through the traditional method. If you’re an experienced developer, I encourage you to experiment with streamlined VBA event procedure coding in Standalone Class Modules and see firsthand how it compares to the traditional coding style.
This approach can offer valuable insights and significantly boost coding efficiency, saving substantial project development time. Moreover, the reusable VBA code in Standalone Class Modules can be easily exported and integrated into other projects, further enhancing productivity.
Streamlined event procedure coding involves more than just moving the code from the form module to the standalone class module. It's about organizing the event procedure code in a structured and concise manner, which promotes reusability without the need for duplicating code for multiple objects of the same type in the form module. This approach enhances code maintainability and reduces redundancy, resulting in a more efficient and manageable codebase.
Direct access to the Structured Event Subroutines in the Standalone Class Module eliminates the need for struggling with the form design view to reach a particular event subroutine. This direct access streamlines the development process, making it easier to locate and modify event procedures without the hassle of navigating through the form's design view.
Example of Structured Event Subroutine Coding:
The BeforeUpdate Event Procedure Code of several TextBoxes can be written within a single BeforeUpdate() Event Subroutine.
Private Sub txt_BeforeUpdate(Cancel As Integer) 'When the BeforeUpdate Event is captured the txt object will have 'the Name of the Object fired the Event Select Case txt.Name Case "Quantity" 'Code Case "UnitPrice" 'Code Case "SaleTax" ' Code Case . . . End Select End Sub
The seventh episode in this series of articles is a prime example of event subroutine code Reuse and illustrates an organized, structured approach to event procedure coding. By writing just one set of GotFocus and LostFocus Event Subroutines, you can efficiently manage the behavior of 25 or more text boxes on the form when they gain or lose focus. This example offers a straightforward demonstration of how to effectively implement the concept of streamlined event procedure coding in a standalone class module, emphasizing code reusability and reduced redundancy.
Microsoft Access controls, such as TextBoxes, Command Buttons, and others, rely on event-defining, event-firing, and event-capturing mechanisms, which form the foundation of streamlined event subroutine coding. I explored these concepts in detail during my presentation to the Access User Groups (Europe) on January 3, 2024. The presentation is available as a YouTube video on the Access User Groups (Europe) channel, titled Streamlined Event Procedure Coding in Standalone Class Modules, offering valuable insights into this coding approach.
In our current project of 'Filter by Character and Sort', the Customers Form’s record source is derived from the CustomersQ query, which contains multiple records. To enhance user experience and efficiency, we’ll implement a technique that swiftly filters records by allowing users to type the first one or more characters from the customer’s selected Data Field. Utilizing the form’s filter settings, matching records will be quickly identified based on the characters typed into a text box control. This feature will streamline the process of locating specific customer records, improving overall usability.
The Customers Form Image-1 Normal Data View.
Customers Form Image-2 with Filtered Data.
The yellow-highlighted TextBox serves as the filter input control. Above it, a ComboBox lets users select the field to search—in this case, the Last Name field. As text is entered into the filter box, the system matches the beginning of the selected field’s value and filters the records accordingly. This setup enables quick and efficient record searches based on starting characters, making it easier to locate specific names that meet the criteria.
In this example, three records are initially filtered, each with a Last Name beginning with the letter G. When you type ‘r’ after ‘G’ in the yellow-highlighted filter box, the first record (which contains ‘Go…’) no longer matches and is removed from the results. This dynamic filtering approach provides precise and efficient record retrieval, updating in real time as users type, and making it easier to quickly locate records that meet the search criteria.
When the Backspace key is pressed to remove the last character from the filter TextBox, the data instantly updates to reflect the new filtering criteria based on the remaining characters. If no characters remain, the filter is cleared and the full dataset is displayed in the form’s detail section. This ensures a seamless, real-time filtering experience that intuitively responds to user input.
The Cls_ObjInit Class Module VBA Code.
Option Compare Database Option Explicit Private WithEvents frm As Access.Form Private WithEvents txt As Access.TextBox Private WithEvents cmd As Access.CommandButton Private WithEvents cbo As Access.ComboBox Dim txt2Filter Public Property Get m_Frm() As Access.Form Set m_Frm = frm End Property Public Property Set m_Frm(ByRef vFrm As Access.Form) Set frm = vFrm Call Class_Init End Property Private Sub Class_Init() Const EP = "[Event Procedure]" Set txt = frm.FilterText Set cmd = frm.cmdClose Set cbo = frm.cboFields With frm .OnLoad = EP .OnUnload = EP End With With txt .OnKeyUp = EP End With With cmd .OnClick = EP End With With cbo .OnClick = EP End With End Sub Private Sub cbo_Click() frm.FilterText = "" txt2Filter = "" frm.Filter = "" frm.FilterText.SetFocus frm.FilterOn = False End Sub Private Sub txt_KeyUp(KeyCode As Integer, Shift As Integer) Dim C As Integer, sort As String Dim L As String On Error GoTo txt_KeyUp_Err C = KeyCode With frm Select Case C Case 8 'backspace key txt2Filter = Nz(![FilterText], "") If Len(txt2Filter) = 1 Or Len(txt2Filter) = 0 Then txt2Filter = "" .FilterOn = False ' remove filter frm.Recalc Else txt2Filter = Left(txt2Filter, Len(txt2Filter) - 1) 'delete the last character If Len(txt2Filter) = 0 Then .FilterOn = False ' remove filter Else 'set filter and enable .Filter = "[" & ![cboFields] & "]" & " like '" & txt2Filter & "*'" ![FilterText] = txt2Filter 'position cursor position at the end of the text If Len(!FilterText) > 0 Then .Section(acFooter).SetTabOrder ![FilterText].SelLength = Len(![FilterText]) SendKeys "{END}" 'position cursor at right end of text End If .FilterOn = True End If End If Case 37 'right arrow key, prevent text highlighting SendKeys "{END}" 'position cursor at right end of text Case 32, 48 To 57, 65 To 90, 97 To 122 'space, 0 to 9, A to Z, a to z keys txt2Filter = txt2Filter & Chr$(C) 'First letter of words to uppercase ![FilterText] = StrConv(txt2Filter, vbProperCase) SendKeys "{END}" GoSub SetFilter End Select End With txt_KeyUp_Exit: Exit Sub SetFilter: With frm .Refresh If Len(txt2Filter) = 0 Then .FilterOn = False ' remove filter Else 'set filter and enable .Filter = "[" & ![cboFields] & "]" & " like '" & txt2Filter & "*'" .FilterOn = True ' Set sort order sort = IIf(!Frame10 = 1, "ASC", "DESC") .OrderBy = "[" & !cboFields & "] " & sort .OrderByOn = True .Section(acFooter).SetTabOrder 'Form Footer Section Active 'position cursor at end of text ![FilterText].SelLength = Len(![FilterText]) SendKeys "{END}" End If End With Return txt_KeyUp_Err: MsgBox Err.Description, , "txt_KeyUp()" Resume txt_KeyUp_Exit End Sub Private Sub cmd_Click() DoCmd.Close acForm, frm.Name End Sub
There are three controls in the footer of the form, each triggering simple events that run corresponding code—except for the TextBox, which handles a more complex KeyUp() event.
In this scenario, creating separate Wrapper Class Objects is unnecessary for the TextBox, ComboBox, and Command Button, since only one instance of each exists on the form.
Within the Cls_ObjInit class module, the main object instances are declared in the global section using the WithEvents keyword, enabling Event capture and execution of their respective subroutines. Additionally, a Variant-type variable, txt2Filter, is declared globally, followed by the Form Property procedures.
The Class_Init() subroutine is then called from the Set m_Frm() property procedure after receiving the form object from the Form_Load() event procedure in the form module.
Next, the txt, cmd, and cbo objects are assigned references to their respective controls on the form and enabled with the required events.
-
The ComboBox Click event selects a field name to serve as the Filter target. This action resets any previously applied filter.
-
The Command Button Click event closes the form.
-
The TextBox KeyUp event captures valid keystrokes, builds the input string character by character, and applies it dynamically as a filter against the field selected in the ComboBox.
The txt_KeyUp() Event Subroutine Code.
Private Sub txt_KeyUp(KeyCode As Integer, Shift As Integer) Dim C As Integer, sort As String Dim L As String On Error GoTo txt_KeyUp_Err C = KeyCode With frm Select Case C Case 8 'backspace key txt2Filter = Nz(![FilterText], "") If Len(txt2Filter) = 1 Or Len(txt2Filter) = 0 Then txt2Filter = "" .FilterOn = False ' remove filter frm.Recalc Else txt2Filter = Left(txt2Filter, Len(txt2Filter) - 1) 'delete the last character If Len(txt2Filter) = 0 Then .FilterOn = False ' remove filter Else 'set filter and enable .Filter = "[" & ![cboFields] & "]" & " like '" & txt2Filter & "*'" ![FilterText] = txt2Filter 'position cursor position at the end of the text If Len(!FilterText) > 0 Then .Section(acFooter).SetTabOrder ![FilterText].SelLength = Len(![FilterText]) SendKeys "{END}" 'position cursor at right end of text End If .FilterOn = True End If End If Case 37 'right arrow key, prevent text highlighting SendKeys "{END}" 'position cursor at right end of text Case 32, 48 To 57, 65 To 90, 97 To 122 'space, 0 to 9, A to Z, a to z keys txt2Filter = txt2Filter & Chr$(C) 'First letter of words to uppercase ![FilterText] = StrConv(txt2Filter, vbProperCase) SendKeys "{END}" GoSub SetFilter End Select End With txt_KeyUp_Exit: Exit Sub SetFilter: With frm .Refresh If Len(txt2Filter) = 0 Then .FilterOn = False ' remove filter Else 'set filter and enable .Filter = "[" & ![cboFields] & "]" & " like '" & txt2Filter & "*'" .FilterOn = True ' Set sort order sort = IIf(!Frame10 = 1, "ASC", "DESC") .OrderBy = "[" & !cboFields & "] " & sort .OrderByOn = True .Section(acFooter).SetTabOrder 'Form Footer Section Active 'position cursor at end of text ![FilterText].SelLength = Len(![FilterText]) SendKeys "{END}" End If End With Return txt_KeyUp_Err: MsgBox Err.Description, , "txt_KeyUp()" Resume txt_KeyUp_Exit End Sub
The Form Module Code.
Option Compare Database Option Explicit 'Global declaration Private obj As New Cls_ObjInit Private Sub Form_load() Set obj.m_Frm = Me Application.SetOption "Behavior Entering Field", 2 End Sub Private Sub Form_Unload(Cancel As Integer) Application.SetOption "Behavior Entering Field", 0 Set obj = Nothing End Sub
Filter By Character in ComboBox Items.
The screenshot above shows the second form, Customers_Combo, which demonstrates the Filter by Character feature applied to ComboBox items. The KeyUp() event subroutine is almost identical to the filter method used in the first form we reviewed earlier.
For this form, a new class module named Cbo_ObjInit has been introduced. The VBA code for the Cbo_ObjInit class module is provided below:
Option Compare Database Option Explicit Private WithEvents frm As Access.Form Private WithEvents txt As Access.TextBox Private WithEvents cmd As Access.CommandButton Private cbo As Access.ComboBox Dim txt2Filter Public Property Get m_Frm() As Access.Form Set m_Frm = frm End Property Public Property Set m_Frm(ByRef vFrm As Access.Form) Set frm = vFrm Call Class_Init End Property Private Sub Class_Init() Const EP = "[Event Procedure]" Set txt = frm.FilterText Set cmd = frm.cmdExit Set cbo = frm.cboCust With frm .OnLoad = EP .OnUnload = EP End With With txt .OnKeyUp = EP End With With cmd .OnClick = EP End With End Sub Private Sub txt_KeyUp(KeyCode As Integer, Shift As Integer) Dim i As Integer Dim SQL As String Dim SQL1 As String Dim SQL2 As String On Error GoTo txtKeyUp_Err SQL = "SELECT CustomersQ.* FROM CustomersQ ORDER BY CustomersQ.[Last Name];" SQL1 = "SELECT CustomersQ.* FROM CustomersQ " SQL2 = "WHERE (((CustomersQ.[Last Name]) Like '" '"Gr*")); i = KeyCode Select Case i Case 8 'backspace key frm.Refresh If Len(txt2Filter) = 1 Or Len(txt2Filter) = 0 Then txt2Filter = "" Else txt2Filter = Left(txt2Filter, Len(txt2Filter) - 1) 'delete the last character End If GoSub SetFilter Case 37 'right arrow keys SendKeys "{END}" Case 32, 48 To 57, 65 To 90, 97 To 122 'space, 0 to 9, A to Z, a to z keys txt2Filter = txt2Filter & Chr$(i) frm![FilterText] = StrConv(txt2Filter, vbProperCase) GoSub SetFilter End Select txtKeyUp_Exit: Exit Sub SetFilter: If Len(Nz(txt2Filter, "")) = 0 Then With frm .cboCust.RowSource = SQL .cboCust.Requery .cboCust.SetFocus .cboCust.Dropdown End With Else 'set filter and enable SQL = SQL1 & SQL2 & txt2Filter & "*'));" With frm .cboCust.RowSource = SQL .cboCust.Requery .cboCust.SetFocus .cboCust.Dropdown End With End If Return txtKeyUp_Err: MsgBox Err.Description, , "txtKeyUp()" Resume txtKeyUp_Exit End Sub Private Sub cmd_Click() DoCmd.Close acForm, frm.Name End Sub
In the earlier approach, we applied the Form Filter method, where the characters entered into a TextBox served as filter criteria to restrict the records displayed in the form’s record source.
In contrast, the ComboBox method dynamically builds an SQL statement using the filter text entered into a TextBox. This SQL is then assigned to the Row Source of the ComboBox, refreshing its contents in real time based on the updated criteria.
Download Demo Database
- 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 Eleven
- 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.