Calling A Procedure In A Standard Module From A Userform Control Event

Ark68

Well-known Member
Joined
Mar 23, 2004
Messages
4,564
Office Version
  1. 365
  2. 2016
Platform
  1. Windows
I have a userform with 8 labels and 8 textboxes. The textboxes follow the same naming convention: tb_s#_reline, where # is the respective textbox number (1-8)
Each of the 8 textboxes have the same exit event code, differing only in their interaction with other controls associated with the same number (ie tb_s7_reline.exit code applies a property value to label7).

In an effort to not have to repeat the same code 8 different times for each of the 8 exit exents, is it possible to code the exit events to code in a standard module? Here is my logic, I just need to know if it's possible, and some guidance as to how to refer to the controls from within the module.

This code is conceptual only, just to kind of share my thoughts.

Code:
Public userform_test as object   'the userform object
Public frmno as long  'the unique control ID (1-8)

Set userform_test  = userform1

Code:
Private Sub cbx_s1_rln_Click()
     frmno = 1
     cbx_reline frmno
End Sub

This is where I am most uncertain...

Code:
Sub cbx_reline (frmno as long)
     With userform_test
        If .controls("tb_s" & frmno & "_reline").Value = "" Then
            .controls("tb_s" & frmno & "_reline").backcolor = vbred
            .controls("tb_s" & frmno & "_reline").enabled = false
            .controls("label" & frmno).enabled = false
        End If
     End With
End Sub

In my tinkering, I get an "object required" error when referencing the .controls. If I add 'Me' to .controls, I get an "Invalid use of Me keyword"
I would Google but I'm unsure of the best search terms.
 

Excel Facts

Links? Where??
If Excel says you have links but you can't find them, go to Formulas, Name Manager. Look for old links to dead workbooks & delete.
Hi,
see if this update to your code does what you want

STANDARD MODULE
VBA Code:
Sub cbx_reline(ByVal Form As Object, ByVal Index As Integer)

        With Form.Controls("tb_s" & Index)
        If Len(.Value) = 0 Then
            .BackColor = vbRed
            .Enabled = False
         End If
         Form.Controls("label" & Index).Enabled = .Enabled
     End With
     
End Sub

and to call it from your userform

VBA Code:
Private Sub cbx_s1_rln_Click()
     cbx_reline Me, 1
End Sub

Change the control index number for each event as required

Dave
 
Upvote 0
Hi,
See if this update to your code does what you want

STANDARD MODULE
VBA Code:
Sub cbx_reline(ByVal Form As Object, ByVal Index As Integer)

        With Form.Controls("tb_s" & Index)
        If Len(.Value) = 0 Then
            .BackColor = vbRed
            .Enabled = False
         End If
         Form.Controls("label" & Index).Enabled = .Enabled
     End With
 
End Sub

and to call it from your userform

VBA Code:
Private Sub cbx_s1_rln_Click()
     cbx_reline Me, 1
End Sub

Change the control index number as required

Dave
 
Upvote 0
Solution
That's awesome Dave! Thank you!!!
I was getting caught up on how to use CONTROLS. All makes sense now.
 
Upvote 0
That's awesome Dave! Thank you!!!
I was getting caught up on how to use CONTROLS. All makes sense now.

welcome glad suggestion helps

Appreciate feedback

Dave
 
Upvote 0

Forum statistics

Threads
1,223,236
Messages
6,170,912
Members
452,366
Latest member
TePunaBloke

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top