Userform Data Entry Validation - VBA Code

browalex

New Member
Joined
Oct 29, 2013
Messages
4
I am new here, so I hope this is an appropriate thread / question for this forum. Thanks in advance for any input or help that you can offer.

I'm looking at using a userform for a quality technician to populate with dimensional data from our product. The userform is made up of multiple text boxes (textbox1 - 6) that I'd like to have ONLY numeric data entered into, and a combobox with a selection of geographical locations. The goal is to take these values and input them into rows of a separate worksheet ("Data") such that I can keep things organized and build graphs from. I have the data logging aspect functioning properly, but I'm having problems validating that the text box entries are numeric for the text box's, and if it is not, prompting the user to go back to the invalid entry and correct it. I'd like to have a message box to appear and request only numeric values when OK button is executed if they are in fact not Numeric. However, at the top of the userform there is a combobox that is populated with the locations of our facilities (Brazil, Fuzhou, Guelph, US, etc). I need to make sure that this is not empty when OK is executed as well; prompting the user to populate this combobox if indeed it is empty when selecting OK. What would this code look like, and where would it reside?


Private Sub CommandButton1_Click()
Dim LastRow As Object
Dim ws As Worksheet
Set ws = Worksheets("Data")

'Open the Storage Sheet for the Raw Data
Sheets("Data").Activate

'Find next empty row in "Data" sheet
Set LastRow = Sheets("Data").Range("A65536").End(xlUp)

'Insert data into cells
With LastRow
.Offset(1, 0) = ComboBox1.Text
.Offset(1, 1) = TextBox1.Value
.Offset(1, 2) = TextBox2.Value
.Offset(1, 3) = TextBox3.Value
.Offset(1, 4) = TextBox4.Value
.Offset(1, 5) = TextBox5.Value
.Offset(1, 6) = TextBox6.Value
End With

'Clear all the Entries Back to Blank
ComboBox1.Text = ""
TextBox1.Value = ""
TextBox2.Value = ""
TextBox3.Value = ""
TextBox4.Value = ""
TextBox5.Value = ""
TextBox6.Value = ""

'Set the data entry focus back to the first ComboBox1
ComboBox1.SetFocus
Unload UserForm1
End Sub


Thanks for your time!
Alex
 
Last edited:
Try such a function
Code:
Private Function hasNumeric(ByVal control As MSForms.control) As Boolean
On Error GoTo errHandle
    Dim tmp As Double
    tmp = CDbl(control.Value)
    hasNumeric = True
Exit Function
errHandle:
    control.SetFocus
    MsgBox "it is needed a numeric value here", vbOKOnly + vbInformation, "Mistake"
    hasNumeric = False
End Function
with using it
Code:
'Insert data into cells
With LastRow
If Not hasNumeric(ComboBox1) Then Exit Sub
.Offset(1, 0) = ComboBox1.Text
If Not hasNumeric(TextBox1) Then Exit Sub
.Offset(1, 1) = TextBox1.Value
'...
Regards,
 
Upvote 0
Code:
[color=darkblue]Private[/color] [color=darkblue]Sub[/color] CommandButton1_Click()

    [color=darkblue]Dim[/color] i [color=darkblue]As[/color] [color=darkblue]Integer[/color]
    
    [color=green]'Validate combobox1[/color]
    [color=darkblue]If[/color] ComboBox1.ListIndex = -1 [color=darkblue]Then[/color]
        MsgBox "Missing or invalid location. ", vbExclamation, "Invalid Location"
        ComboBox1.SetFocus
        [color=darkblue]Exit[/color] [color=darkblue]Sub[/color]
    [color=darkblue]End[/color] [color=darkblue]If[/color]
    
    [color=green]'Validate textboxes 1 to 6[/color]
    [color=darkblue]For[/color] i = 1 [color=darkblue]To[/color] 6
        [color=darkblue]With[/color] Me.Controls("Textbox" & i)
            [color=darkblue]If[/color] Len(.Value) = 0 [color=darkblue]Or[/color] [color=darkblue]Not[/color] IsNumeric(.Value) [color=darkblue]Then[/color]
                .SetFocus
                MsgBox "Missing or invalid numeric value. ", vbExclamation, "Invalid Number Entry"
                [color=darkblue]Exit[/color] [color=darkblue]Sub[/color]
            [color=darkblue]End[/color] [color=darkblue]If[/color]
        [color=darkblue]End[/color] [color=darkblue]With[/color]
    [color=darkblue]Next[/color] i
    
    [color=green]'Data validated[/color]
    [color=green]'Populate "Data" worksheet[/color]
    [color=darkblue]With[/color] Worksheets("Data")
        [color=green]'Open the Storage Sheet for the Raw Data[/color]
        .Activate
        [color=green]'Insert data into cells[/color]
        [color=green]'next empty row in "Data" sheet[/color]
        [color=darkblue]With[/color] .Range("A65536").End(xlUp)
            .Offset(1, 0) = ComboBox1.Text
            .Offset(1, 1) = TextBox1.Value
            .Offset(1, 2) = TextBox2.Value
            .Offset(1, 3) = TextBox3.Value
            .Offset(1, 4) = TextBox4.Value
            .Offset(1, 5) = TextBox5.Value
            .Offset(1, 6) = TextBox6.Value
        [color=darkblue]End[/color] [color=darkblue]With[/color]
    [color=darkblue]End[/color] [color=darkblue]With[/color]
    
    Unload UserForm1
            
[color=darkblue]End[/color] [color=darkblue]Sub[/color]

[color=darkblue]Private[/color] [color=darkblue]Sub[/color] TextBox1_KeyPress([color=darkblue]ByVal[/color] KeyAscii As MSForms.ReturnInteger)
    Validate_Numeric TextBox1, KeyAscii
[color=darkblue]End[/color] [color=darkblue]Sub[/color]

[color=darkblue]Private[/color] [color=darkblue]Sub[/color] TextBox2_KeyPress([color=darkblue]ByVal[/color] KeyAscii As MSForms.ReturnInteger)
    Validate_Numeric TextBox2, KeyAscii
[color=darkblue]End[/color] [color=darkblue]Sub[/color]

[color=darkblue]Private[/color] [color=darkblue]Sub[/color] TextBox3_KeyPress([color=darkblue]ByVal[/color] KeyAscii As MSForms.ReturnInteger)
    Validate_Numeric TextBox3, KeyAscii
[color=darkblue]End[/color] [color=darkblue]Sub[/color]

[color=darkblue]Private[/color] [color=darkblue]Sub[/color] TextBox4_KeyPress([color=darkblue]ByVal[/color] KeyAscii As MSForms.ReturnInteger)
    Validate_Numeric TextBox4, KeyAscii
[color=darkblue]End[/color] [color=darkblue]Sub[/color]

[color=darkblue]Private[/color] [color=darkblue]Sub[/color] TextBox5_KeyPress([color=darkblue]ByVal[/color] Key[color=darkblue]As[/color]cii As MSForms.ReturnInteger)
    Validate_Numeric TextBox5, KeyAscii
[color=darkblue]End[/color] [color=darkblue]Sub[/color]

[color=darkblue]Private[/color] [color=darkblue]Sub[/color] TextBox6_KeyPress([color=darkblue]ByVal[/color] KeyAscii As MSForms.ReturnInteger)
    Validate_Numeric TextBox6, KeyAscii
[color=darkblue]End[/color] [color=darkblue]Sub[/color]

[color=darkblue]Private[/color] [color=darkblue]Sub[/color] Validate_Numeric([color=darkblue]ByRef[/color] TB As MSForms.TextBox, [color=darkblue]ByRef[/color] KeyAscii As MSForms.ReturnInteger)
    [color=green]'Allow keyboard entries of 0-9, one decimal, and one leading minus.[/color]
    [color=darkblue]With[/color] TB
        [color=darkblue]Select[/color] [color=darkblue]Case[/color] KeyAscii
            [color=darkblue]Case[/color] Asc("0") [color=darkblue]To[/color] Asc("9")
            [color=darkblue]Case[/color] Asc("."): [color=darkblue]If[/color] InStr(.Value, ".") [color=darkblue]Then[/color] KeyAscii = 0: Beep
            [color=darkblue]Case[/color] Asc("-"): [color=darkblue]If[/color] Len(.Value) [color=darkblue]Then[/color] KeyAscii = 0: Beep
            [color=darkblue]Case[/color] Else: KeyAscii = 0: Beep
        [color=darkblue]End[/color] [color=darkblue]Select[/color]
    [color=darkblue]End[/color] [color=darkblue]With[/color]
[color=darkblue]End[/color] [color=darkblue]Sub[/color]
 
Upvote 0
Everything works flawlessly, thank you for saving the day!

One other question: I'd like to limit the text box numeric values to decimals only (4 decimal places available, but not required)... I don't have a particular range, but these measurements will never exceed 1.0". How would I alter your last bit of code here that allows keyboard entries 0 - 9 with a single decimal place, to give me what I need?


Code:
[COLOR=darkblue]Private[/COLOR] [COLOR=darkblue]Sub[/COLOR] CommandButton1_Click()

[COLOR=darkblue]Private[/COLOR] [COLOR=darkblue]Sub[/COLOR] Validate_Numeric([COLOR=darkblue]ByRef[/COLOR] TB As MSForms.TextBox, [COLOR=darkblue]ByRef[/COLOR] KeyAscii As MSForms.ReturnInteger)
    [COLOR=green]'Allow keyboard entries of 0-9, one decimal, and one leading minus.[/COLOR]
    [COLOR=darkblue]With[/COLOR] TB
        [COLOR=darkblue]Select[/COLOR] [COLOR=darkblue]Case[/COLOR] KeyAscii
            [COLOR=darkblue]Case[/COLOR] Asc("0") [COLOR=darkblue]To[/COLOR] Asc("9")
            [COLOR=darkblue]Case[/COLOR] Asc("."): [COLOR=darkblue]If[/COLOR] InStr(.Value, ".") [COLOR=darkblue]Then[/COLOR] KeyAscii = 0: Beep
            [COLOR=darkblue]Case[/COLOR] Asc("-"): [COLOR=darkblue]If[/COLOR] Len(.Value) [COLOR=darkblue]Then[/COLOR] KeyAscii = 0: Beep
            [COLOR=darkblue]Case[/COLOR] Else: KeyAscii = 0: Beep
        [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]Select[/COLOR]
    [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]With[/COLOR]
[COLOR=darkblue]End[/COLOR] [COLOR=darkblue]Sub[/COLOR]
 
Upvote 0
Code:
    [COLOR=green]'Validate textboxes 1 to 6[/COLOR]
    [COLOR=darkblue]For[/COLOR] i = 1 [COLOR=darkblue]To[/COLOR] 6
        [COLOR=darkblue]With[/COLOR] Me.Controls("Textbox" & i)
            [COLOR=darkblue]If[/COLOR] Len(.Value) = 0 [COLOR=darkblue]Or[/COLOR] [COLOR=darkblue]Not[/COLOR] [B][COLOR=#b22222]IsNumeric[/COLOR][/B](.Value) [COLOR=darkblue]Then[/COLOR]
                .SetFocus
                MsgBox "Missing or invalid numeric value. ", vbExclamation, "Invalid Number Entry"
                [COLOR=darkblue]Exit[/COLOR] [COLOR=darkblue]Sub[/COLOR]
            [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]If[/COLOR]
        [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]With[/COLOR]
    [COLOR=darkblue]Next[/COLOR] i
I would suggest using WorksheetFunction.IsNumber instead of IsNumeric. Below is something I have been posting on-and-off for many years now (starting back in my volunteering days for the compiled version of Visual Basic which preceeded my volunteering days for Excel) which explains why I am making this recommendation. Note that the worksheet's IsNumber function takes the place of some of the code included in my message (which would still work if used in Excel's VBA by the way), but I left it in for completeness.

I usually try and steer people away from using IsNumeric to "proof" supposedly numeric text. Consider this (also see note below):

Rich (BB code):
ReturnValue = IsNumeric("($1,23,,3.4,,,5,,E67$)")

Most people would not expect THAT to return True. IsNumeric has some "flaws" in what it considers a proper number and what most programmers are looking for.

I had a short tip published by Pinnacle Publishing in their Visual Basic Developer magazine that covered some of these flaws. Originally, the tip was free to view but is now viewable only by subscribers.. Basically, it said that IsNumeric returned True for things like -- currency symbols being located in front or in back of the number as shown in my example (also applies to plus, minus and blanks too); numbers surrounded by parentheses as shown in my example (some people use these to mark negative numbers); numbers containing any number of commas before a decimal point as shown in my example; numbers in scientific notation (a number followed by an upper or lower case "D" or "E", followed by a number equal to or less than 307 -- the maximum power of 10 in VB); and Octal/Hexadecimal numbers (&H for Hexadecimal, &O or just & in front of the number for Octal).

NOTE:
======
In the above example and in the referenced tip, I refer to $ signs and commas and dots -- these were meant to refer to your currency, thousands separator and decimal point symbols as defined in your local settings -- substitute your local regional symbols for these if appropriate.

As for your question about checking numbers, here are two functions that I have posted in the past for similar questions..... one is for digits only and the other is for "regular" numbers (the code is simple enough that it can be pulled from the function "housing" and used directly inside your own code):

Rich (BB code):
Function IsDigitsOnly(Value As String) As Boolean
    IsDigitsOnly = Len(Value) > 0 And Not Value Like "*[!0-9]*"
End Function

Function IsNumber(ByVal Value As String) As Boolean
    '   Leave the next statement out if you don't
    '   want to provide for plus/minus signs
    If Value Like "[+-]*" Then Value = Mid$(Value, 2)
    IsNumber = Not Value Like "*[!0-9.]*" And Not Value Like "*.*.*" And Len(Value) > 0 And Value <> "."
End Function

Here are revisions to the above functions that deal with the local settings for decimal points (and thousand's separators) that are different than used in the US (this code works in the US too, of course).

Rich (BB code):
Function IsNumber(ByVal Value As String) As Boolean
  Dim DP As String
  '   Get local setting for decimal point
  DP = Format$(0, ".")
  '   Leave the next statement out if you don't
  '   want to provide for plus/minus signs
  If Value Like "[+-]*" Then Value = Mid$(Value, 2)
  IsNumber = Not Value Like "*[!0-9" & DP & "]*" And Not Value Like "*" & _
             DP & "*" & DP & "*" And Len(Value) > 0 And Value <> DP
End Function

I'm not as concerned by the rejection of entries that include one or more thousand's separators, but we can handle this if we don't insist on the thousand's separator being located in the correct positions (in other words, we'll allow the user to include them for their own purposes... we'll just tolerate their presence).

Rich (BB code):
Function IsNumber(ByVal Value As String) As Boolean
  Dim DP As String
  Dim TS As String
  '   Get local setting for decimal point
  DP = Format$(0, ".")
  '   Get local setting for thousand's separator
  '   and eliminate them. Remove the next two lines
  '   if you don't want your users being able to
  '   type in the thousands separator at all.
  TS = Mid$(Format$(1000, "#,###"), 2, 1)
  Value = Replace$(Value, TS, "")
  '   Leave the next statement out if you don't
  '   want to provide for plus/minus signs
  If Value Like "[+-]*" Then Value = Mid$(Value, 2)
  IsNumber = Not Value Like "*[!0-9" & DP & "]*" And Not Value Like "*" & _
             DP & "*" & DP & "*" And Len(Value) > 0 And Value <> DP
End Function
 
Upvote 0
Everything works flawlessly, thank you for saving the day!

One other question: I'd like to limit the text box numeric values to decimals only (4 decimal places available, but not required)... I don't have a particular range, but these measurements will never exceed 1.0". How would I alter your last bit of code here that allows keyboard entries 0 - 9 with a single decimal place, to give me what I need?

You're welcome.

This limits the decimal to four places (0.0000) max and values between +1 and -1.

Code:
[COLOR=darkblue]Private[/COLOR] [COLOR=darkblue]Sub[/COLOR] Validate_Numeric([COLOR=darkblue]ByRef[/COLOR] TB [COLOR=darkblue]As[/COLOR] MSForms.TextBox, [COLOR=darkblue]ByRef[/COLOR] KeyAscii As MSForms.ReturnInteger)
    [COLOR=green]'Allow keyboard entries of 0-9, four decimal places max, one decimal point, and one leading minus.[/COLOR]
    [COLOR=darkblue]With[/COLOR] TB
        [COLOR=darkblue]Select[/COLOR] [COLOR=darkblue]Case[/COLOR] KeyAscii
            [COLOR=darkblue]Case[/COLOR] Asc("0") [COLOR=darkblue]To[/COLOR] Asc("9")
                [COLOR=darkblue]If[/COLOR] Len(Replace(.Value, "-", "")) = 0 [COLOR=darkblue]Then[/COLOR]
                    .Value = .Value & "0."
                    [COLOR=darkblue]If[/COLOR] KeyAscii = Asc("0") [COLOR=darkblue]Then[/COLOR] KeyAscii = 0
                [COLOR=darkblue]ElseIf[/COLOR] Len(Replace(.Value, "-", "")) > 5 [COLOR=darkblue]Then[/COLOR]
                    KeyAscii = 0: Beep
                [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]If[/COLOR]
            [COLOR=darkblue]Case[/COLOR] Asc("."): [COLOR=darkblue]If[/COLOR] InStr(.Value, ".") [COLOR=darkblue]Then[/COLOR] KeyAscii = 0: Beep
            [COLOR=darkblue]Case[/COLOR] Asc("-"): [COLOR=darkblue]If[/COLOR] Len(.Value) [COLOR=darkblue]Then[/COLOR] KeyAscii = 0: Beep
            [COLOR=darkblue]Case[/COLOR] Else: KeyAscii = 0: Beep
        [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]Select[/COLOR]
    [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]With[/COLOR]
[COLOR=darkblue]End[/COLOR] [COLOR=darkblue]Sub[/COLOR]
 
Upvote 0
Here is a different way to do what (I think) you want. The following code will stop the entry of invalid data before it is allowed to be entered. So, the user will only be able to enter characters that produce a 1 or -1 (with a trailing dot which would be immaterial when evaluating the text value as a number) or a decimal point, or a 0 followed by a decimal point, possibly preceeded by a minus sign, followed by no more than 4 digits... all other attempts to produce a value different from this will produce a beep and the character will not be entered into the TextBox. Because of the necessity to allow a decimal point, the possibility that a single decimal point might be entered into the TextBox, so the CommandButton is used to filter those entries out (the user will be alerted to the error and returned to the offending TextBox). I am also using a Class Module to establish a single set of events that will apply to your six TextBoxes. So, let's get started.

Add a Class Module to your project ("Insert/Class Module" on the VB editor's menu bar) and copy/paste the following code into the code window that opened up...

Code:
Public WithEvents Class1 As MSForms.TextBox

Public LastPosition As Long

Private Sub Class1_Change()
  Static LastText As String
  Static SecondTime As Boolean
  Const MaxDecimal As Integer = 4
  Const MaxWhole As Integer = 1
  With Class1
    If Not SecondTime Then
      If .Text Like "[!01.-]*" Or .Text Like "?*[!0-9.-]*" Or Val(.Text) < -1 Or Val(.Text) > 1 Or _
         .Text Like "*.*.*" Or .Text Like "*." & String$(1 + MaxDecimal, "#") Or .Text Like "?*[!0-9.]*" Then
        Beep
        SecondTime = True
        .Text = LastText
        .SelStart = LastPosition
       Else
        LastText = .Text
      End If
    End If
  End With
  SecondTime = False
End Sub

Next, copy/paste the following code into the code window for your UserForm (comment out any code you have there now as it would interfere with this code)...

Code:
Dim TextBoxes() As New Class1

Private Sub CommandButton1_Click()
  Dim X As Long
  For X = 1 To 6
    If Controls("TextBox" & X) = "." Then
      MsgBox "You cannot enter only a decimal point in the TextBoxes... " & _
              vbLf & vbLf & "Please try again.", vbExclamation
      With Controls("TextBox" & X)
        .SelStart = 0
        .SelLength = 1
        .SetFocus
      End With
    End If
  Next
End Sub

Private Sub UserForm_Initialize()
  Dim Counter As Integer, Obj As Control
  For Each Obj In Me.Controls
    If Obj.Name Like "TextBox[1-6]" Then
      Counter = Counter + 1
      ReDim Preserve TextBoxes(1 To Counter)
      Set TextBoxes(Counter).Class1 = Obj
    End If
  Next
  Set Obj = Nothing
End Sub

Dim TextBoxes() As New Class1
Private Sub CommandButton1_Click()
  Dim X As Long
  For X = 1 To 6
    If Controls("TextBox" & X) = "." Then
      MsgBox "You cannot enter only a decimal point in the TextBoxes... " & _
              vbLf & vbLf & "Please try again.", vbExclamation
      With Controls("TextBox" & X)
        .SelStart = 0
        .SelLength = 1
        .SetFocus
      End With
    End If
  Next
End Sub

Private Sub UserForm_Initialize()
  Dim Counter As Integer, Obj As Control
  For Each Obj In Me.Controls
    If Obj.Name Like "TextBox[1-6]" Then
      Counter = Counter + 1
      ReDim Preserve TextBoxes(1 To Counter)
      Set TextBoxes(Counter).Class1 = Obj
    End If
  Next
  Set Obj = Nothing
End Sub

ASSUMPTIONS: The CommandButton is named CommandButton1; the six TextBoxes are named TextBox1, TextBox2, TextBox3, TextBox4, TextBox5 and TextBox6; and the Class Module is named Class1. All of these names will probably be the default names that were assigned to these objects, but I decided to mention it "just in case".

Okay, that is it... show your UserForm and try to enter non-numbers into any of your six TextBoxes (don't forget to test putting just a single decimal point into one of the TextBoxes to see what happens when you click the CommandButton.
 
Upvote 0
Again, this works excellent! Just what I needed, thank you for taking the time to help me out!

Alex
 
Upvote 0
Again, this works excellent! Just what I needed, thank you for taking the time to help me out!
Just wondering if you had a chance to try the solution I suggested in Message #7? No problem if you didn't, I was just curious what you thought about it if you did.
 
Upvote 0

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