In VBA are "Variable" Variable Userform Object Names Possible?

jardenp

Active Member
Joined
May 12, 2009
Messages
373
Office Version
  1. 2019
  2. 2016
  3. 2013
  4. 2011
  5. 2010
Platform
  1. Windows
In a Userform I have three groups of maybe 30 text boxes, command buttons, radio buttons, etc. The groups are identical except for the number in the object names. For example, I have 3 text boxes: LastName_TB1, LastName_TB2, and LastName_TB3; or 3 command buttons: ProcessScan_CB1, ProcessScan_CB2, and ProcessScan_CB3. It's in groups because I have command buttons that copy certain data down to the next group, making it much faster for the person entering data.

At the bottom there is a command button to process the data. That command button will run a series of checks and data moves to each group separately.

Is there a way to write a script that I could run a 3-iteration loop on to change the object names or do I just need to make copies of the finished scripts and, say, replace all "TB1" with "TB2", "CB1" with "CB2", etc.? I'm thinking something along the lines of
VBA Code:
For i = 1 to 3
    ...
    LastName_TB&i.copy Sheets(Destination)...
    ...
Next i
Where "i" become part of the object name.

I mean...I can copy and replace...but it's probably 250 lines of code to "process" a group, any future change would have to be made in three places, sounds like a pain to get straight, reading through copies to make sure the find and replace went ok, etc.

Thank you!
 

Excel Facts

Why does 9 mean SUM in SUBTOTAL?
It is because Sum is the 9th alphabetically in Average, Count, CountA, Max, Min, Product, StDev.S, StDev.P, Sum, VAR.S, VAR.P.
You can do it like
VBA Code:
   Dim i As Long
   
   For i = 1 To 3
      Sheets("Destination").Range("F" & i).Value = Me.Controls("LastName_TB" & i)
   Next i
 
Upvote 0
Solution
You can do it like
VBA Code:
   Dim i As Long
  
   For i = 1 To 3
      Sheets("Destination").Range("F" & i).Value = Me.Controls("LastName_TB" & i)
   Next i
Thank you, Fluff! That's exactly what I was looking for!
 
Upvote 0
One quick follow up, if I may: does this also work on normal variable names? If not, is there a similar solution for those? I'm thinking of Integer, Date, etc. names.
 
Upvote 0
No it doesn't work for variables, however you could us an array
Rich (BB code):
   Dim aryNames As Variant
  
   aryNames = Array("Tom", "Dick", "Harry")
   Debug.Print aryNames(2)
 
Upvote 0
How would I use that to get, say, a message boxes to display "2" then "3" here?
VBA Code:
Dim aryNames As Variant
Dim i As Integer
Dim num1 As Integer: num1 = 2
Dim num2 As Integer: num2 = 3

For i = 1 To 2

   aryNames = Array("num", i)
   MsgBox aryNames
Next i
I'm not familiar with how arrays work, so I'm just experimenting here.
 
Upvote 0
Like
VBA Code:
Dim aryNum(1 To 2) As Long
Dim i As Integer

aryNum(1) = 2
aryNum(2) = 3
For i = 1 To 2
   MsgBox aryNum(i)
Next i
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,214,837
Messages
6,121,883
Members
449,057
Latest member
Moo4247

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