View Single Post
  #5   Report Post  
Posted to microsoft.public.excel.worksheet.functions
Rick Rothstein Rick Rothstein is offline
external usenet poster
 
Posts: 5,934
Default VBA data validation

Your code will permit certain non-numbers to be able to be typed into the
TextBox. Try doing the following with your code... type in 43210 in the
TextBox, then move the cursor to between the 3 and the 2 and type either d,
D, e or E and then exit the TextBox. Here is another one to try... type 1234
into the text box, then move the cursor in front of the 1 and type a your
local currency symbol (here in the US, that would be a $ sign), then do the
same thing after the 4 and then exit the TextBox. One more... type 12,345
(with the comma as shown) into TextBox and then exit it. A variation on this
last one would be to type in 1,,,,, (a one followed by 5 commas) instead of
the 12,345.

Here is a previous posting of mine what the problem is...

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

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

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 do not
' 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).

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 do not
' 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 am not as concerned by the rejection of entries that include one or more
thousand's separators, but we can handle this if we do not insist on the
thousand's separator being located in the correct positions (in other words,
we will allow the user to include them for their own purposes... we will
just tolerate their presence).

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 do not 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 do not
' 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

--
Rick (MVP - Excel)



"ozgrid.com" wrote in message
...
Use;

Private Sub TextBox1_Change()
If TextBox1 = vbNullString Then Exit Sub

If Not IsNumeric(TextBox1) Then
MsgBox "6 digit numbers only"
TextBox1 = vbNullString
End If
End Sub

Private Sub TextBox1_Exit(ByVal Cancel As MSForms.ReturnBoolean)
If TextBox1 = vbNullString Then Exit Sub

If Len(TextBox1) < 6 Then
MsgBox "6 digit numbers only"
Cancel = True
TextBox1 = vbNullString
End If
End Sub



--
Regards
Dave Hawley
www.ozgrid.com
"KK" wrote in message
...
Hi all,
I have created a textbox input on a userform. I would like to input
the postal code here and would like to dala validate it for a 6
numeric input. Is ther a way to do this