validate textbox value in Userform

robertvdb

Active Member
Joined
Jan 10, 2021
Messages
327
Office Version
  1. 2016
Platform
  1. Windows
I have a Userform with some textboxes. In one of the textboxes, only values 0 to 9 can be entered. Nothing else.

If the user makes an error here, then I can trap this error when he presses the "OK" button.

However, I want to trap it as soon as he leaves the textbox.

So he needs to receive an error message, and his wrong input must be undone.

Can anyone help ?
 

Excel Facts

Copy PDF to Excel
Select data in PDF. Paste to Microsoft Word. Copy from Word and paste to Excel.
Hi,
you just need to limit the data type allowed in the control & the max character lenght.

Try following & see if does what you want

Place in a STANDARD module

VBA Code:
Function NumbersOnly(ByVal KeyAscii As MSForms.ReturnInteger) As MSForms.ReturnInteger
    Select Case KeyAscii
'valid entries [0-9]
    Case 48 To 57
'valid
    Case Else
'cancel
        KeyAscii = 0
    End Select
   
    Set NumbersOnly = KeyAscii
   
    If KeyAscii = 0 Then MsgBox "You can Enter a single number 0-9 only", 16, "Invalid Entry"
End Function

and to call from your textbox

VBA Code:
Private Sub TextBox1_KeyPress(ByVal KeyAscii As MSForms.ReturnInteger)
    With Me.ActiveControl
        .AutoTab = True
        .MaxLength = 1
    End With
    KeyAscii = NumbersOnly(KeyAscii)
End Sub

Change textbox name as required.

Function can be used by other textboxes in your project as needed.


Hope helpful

Dave
 
Upvote 0
Solution

Forum statistics

Threads
1,215,069
Messages
6,122,959
Members
449,096
Latest member
Anshu121

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