vba userform textbox numeric only

jam1531

New Member
Joined
Jan 5, 2015
Messages
29
Hello,

Looking for the code to check a userform textbox to see if anything in it contains anything other than numbers. Basically textbox1 takes the input and finds the numbers, however if someone accidently inserts letter or special character instead of a number it messes my other code up. I would like to add one if in the below code that ensures that textbox1 only contains numbers and if not gives a message box saying "please ensure values are numeric only" and then exits sub. Any help appreciated.

Code:
    If DeleteTool.TextBox1 = "" Then        'Appears if there is no Item input
            MsgBox ("Please insert item number(s)")
                GoTo finish
    End If
 
Last edited:

Excel Facts

Easy bullets in Excel
If you have a numeric keypad, press Alt+7 on numeric keypad to type a bullet in Excel.
Put the next event in your userform, that way only numbers are allowed

Code:
Private Sub TextBox1_KeyPress(ByVal KeyAscii As MSForms.ReturnInteger)
    If Not (KeyAscii >= 48 And KeyAscii <= 57) Then
        KeyAscii = 0
    End If
End Sub
 
Upvote 0
Put the next event in your userform, that way only numbers are allowed

Code:
Private Sub TextBox1_KeyPress(ByVal KeyAscii As MSForms.ReturnInteger)
    If Not (KeyAscii >= 48 And KeyAscii <= 57) Then
        KeyAscii = 0
    End If
End Sub
Your code will not prevent someone from copy/pasting non-digits into the TextBox. The following set of event procedure prevents that and allows the user to only type or copy/paste digits only. Note that the Dim statement for the LastPosition variable lies outside of any procedure and it located at the top of the code window (below any Option statements)...
Code:
[table="width: 500"]
[tr]
	[td]Dim LastPosition As Long

Private Sub TextBox1_Change()
  Static LastText As String
  Static SecondTime As Boolean
  If Not SecondTime Then
    With TextBox1
     If .Text Like "*[!0-9]*" Then
        Beep
        SecondTime = True
        .Text = LastText
        .SelStart = LastPosition
      Else
        LastText = .Text
      End If
    End With
  End If
  SecondTime = False
End Sub

Private Sub TextBox1_MouseDown(ByVal Button As Integer, ByVal Shift As Integer, ByVal X As Single, ByVal Y As Single)
  With TextBox1
    LastPosition = .SelStart
    'Place any other MouseDown event code here
  End With
End Sub

Private Sub TextBox1_KeyPress(ByVal KeyAscii As MSForms.ReturnInteger)
  With TextBox1
    LastPosition = .SelStart
    'Place any other KeyPress checking code here
  End With
End Sub[/td]
[/tr]
[/table]
 
Upvote 0
Your code will not prevent someone from copy/pasting non-digits into the TextBox. The following set of event procedure prevents that and allows the user to only type or copy/paste digits only. Note that the Dim statement for the LastPosition variable lies outside of any procedure and it located at the top of the code window (below any Option statements)...
Code:
[TABLE="width: 500"]
<tbody>[TR]
[TD]Dim LastPosition As Long

Private Sub TextBox1_Change()
  Static LastText As String
  Static SecondTime As Boolean
  If Not SecondTime Then
    With TextBox1
     If .Text Like "*[!0-9]*" Then
        Beep
        SecondTime = True
        .Text = LastText
        .SelStart = LastPosition
      Else
        LastText = .Text
      End If
    End With
  End If
  SecondTime = False
End Sub

Private Sub TextBox1_MouseDown(ByVal Button As Integer, ByVal Shift As Integer, ByVal X As Single, ByVal Y As Single)
  With TextBox1
    LastPosition = .SelStart
    'Place any other MouseDown event code here
  End With
End Sub

Private Sub TextBox1_KeyPress(ByVal KeyAscii As MSForms.ReturnInteger)
  With TextBox1
    LastPosition = .SelStart
    'Place any other KeyPress checking code here
  End With
End Sub[/TD]
[/TR]
</tbody>[/TABLE]

Good contribution
 
Upvote 0
If you want it in your validation and something simple , it could be like this:

Code:
Private Sub CommandButton1_Click()
    'Validations
    If TextBox1 = "" Then        'Appears if there is no Item input
        MsgBox ("Please insert item number(s)")
        TextBox1.SetFocus
        Exit Sub
    End If
    '
    If Not IsNumeric(TextBox1) Then
        MsgBox ("Please ensure values are numeric only")
        TextBox1.SetFocus
        Exit Sub
    End If
    '
    'Here continues your code
    '
End Sub
'
Private Sub TextBox1_KeyPress(ByVal KeyAscii As MSForms.ReturnInteger)
    If Not (KeyAscii >= 48 And KeyAscii <= 57) Then
        KeyAscii = 0
    End If
End Sub
 
Upvote 0
If you want it in your validation and something simple , it could be like this:

Code:
Private Sub CommandButton1_Click()
    'Validations
    If TextBox1 = "" Then        'Appears if there is no Item input
        MsgBox ("Please insert item number(s)")
        TextBox1.SetFocus
        Exit Sub
    End If
    '
    If Not IsNumeric(TextBox1) Then
        MsgBox ("Please ensure values are numeric only")
        TextBox1.SetFocus
        Exit Sub
    End If
    '
    'Here continues your code
    '
End Sub
'
Private Sub TextBox1_KeyPress(ByVal KeyAscii As MSForms.ReturnInteger)
    If Not (KeyAscii >= 48 And KeyAscii <= 57) Then
        KeyAscii = 0
    End If
End Sub
Your suggestion is not robust enough to guaranty the TextBox will only contain digits.

Try copy/pasting any of the following into your TextBox (substitute your thousands separator for the commas and I think your currency symbol for the $ signs) and then press the CommandButton... did you get the response you expected?

&HEAD

(12d3)

$-12$

$(12$)$

1,,,,,2,,,,,,
 
Upvote 0
Your suggestion is not robust enough to guaranty the TextBox will only contain digits.

Try copy/pasting any of the following into your TextBox (substitute your thousands separator for the commas and I think your currency symbol for the $ signs) and then press the CommandButton... did you get the response you expected?

&HEAD

(12d3)

$-12$

$(12$)$

1,,,,,2,,,,,,


It was a suggestion to make it simpler no longer , how about this:



Code:
Private Sub CommandButton1_Click()
    'Validations
    If TextBox1 = "" Then        'Appears if there is no Item input
        MsgBox ("Please insert item number(s)")
        TextBox1.SetFocus
        Exit Sub
    End If
    '
    For i = 1 To Len(TextBox1.Value)
        If InStr(1, "1234567890", Mid(TextBox1, i, 1)) = 0 Then
            MsgBox ("Please ensure values are numeric only")
            TextBox1.SetFocus
            Exit Sub
        End If
    Next
    '
    'Here continues your code
    '
End Sub
'
Private Sub TextBox1_KeyPress(ByVal KeyAscii As MSForms.ReturnInteger)
    If Not (KeyAscii >= 48 And KeyAscii <= 57) Then
        KeyAscii = 0
    End If
End Sub
 
Upvote 0
It was a suggestion to make it simpler no longer , how about this:
Code:
Private Sub CommandButton1_Click()
    'Validations
    If TextBox1 = "" Then        'Appears if there is no Item input
        MsgBox ("Please insert item number(s)")
        TextBox1.SetFocus
        Exit Sub
    End If
    '
    For i = 1 To Len(TextBox1.Value)
        If InStr(1, "1234567890", Mid(TextBox1, i, 1)) = 0 Then
            MsgBox ("Please ensure values are numeric only")
            TextBox1.SetFocus
            Exit Sub
        End If
    Next
    '
    'Here continues your code
    '
End Sub
'
Private Sub TextBox1_KeyPress(ByVal KeyAscii As MSForms.ReturnInteger)
    If Not (KeyAscii >= 48 And KeyAscii <= 57) Then
        KeyAscii = 0
    End If
End Sub
That's much better. You might find the following interesting...
From a previous post of mine...

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

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):

Code:
[table="width: 500"]
[tr]
	[td]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[/td]
[/tr]
[/table]

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).

Code:
[table="width: 500"]
[tr]
	[td]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[/td]
[/tr]
[/table]

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).

Code:
[table="width: 500"]
[tr]
	[td]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[/td]
[/tr]
[/table]
 
Upvote 0
It was a suggestion to make it simpler no longer , how about this:
Code:
Private Sub CommandButton1_Click()
    'Validations
    If TextBox1 = "" Then        'Appears if there is no Item input
        MsgBox ("Please insert item number(s)")
        TextBox1.SetFocus
        Exit Sub
    End If
    '
    For i = 1 To Len(TextBox1.Value)
        If InStr(1, "1234567890", Mid(TextBox1, i, 1)) = 0 Then
            MsgBox ("Please ensure values are numeric only")
            TextBox1.SetFocus
            Exit Sub
        End If
    Next
    '
    'Here continues your code
    '
End Sub
'
Private Sub TextBox1_KeyPress(ByVal KeyAscii As MSForms.ReturnInteger)
    If Not (KeyAscii >= 48 And KeyAscii <= 57) Then
        KeyAscii = 0
    End If
End Sub
I think you might find this interesting. Below is a modification of your code that, one, uses the Like operator to eliminate the For..Next loop, two, restructures your to If..Then blocks into an If..ElseIf..Else block (both of the above in the Click event) and modified your If..Then logical expression in the KeyPress event.
Code:
Private Sub CommandButton1_Click()
  'Validations
  If TextBox1 = "" Then        'Appears if there is no Item input
    MsgBox ("Please insert item number(s)")
    TextBox1.SetFocus
  ElseIf TextBox1 Like "*[!0-9]*" Then
    MsgBox ("Please ensure values are numeric only")
    TextBox1.SetFocus
  Else
    '
    '  Any other CommandButton Click event code goes here
    '
  End If
End Sub
'
Private Sub TextBox1_KeyPress(ByVal KeyAscii As MSForms.ReturnInteger)
  If KeyAscii < 48 Or KeyAscii > 57 Then
    KeyAscii = 0
  End If
End SubR
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,897
Messages
6,175,270
Members
452,628
Latest member
dd2

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