Below are a couple of items that I have posted previously that you may find
interesting and useful...
************************************
* First Previous Posting
************************************
Below is something I have posted previously over in the compiled VB
newsgroups, but everything discussed in it applies to VBA world as well....
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 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 <> "." And _
Value <> vbNullString
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 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 And _
Value <> vbNullString
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).
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 And _
Value <> vbNullString
End Function
************************************
* Second Previous Posting
************************************
Here is some code which I have posted in the past that is fully bullet-proof
entry-wise (read the Notes section carefully though as it deals with some
things you have to account for though). The following is general in nature;
there is code below for both entries with digits only and for entries with
decimal points... you will want to look at the second part of my posting
which deals with floating point numbers. Also note that the code for
floating point numbers requires you to specify a maximum number of digits
that can be typed into both the integer part of the number as well as the
decimal part of the number... if you don't want to place a limit on the
user, just set each one to large value.
The routines work quite well and protects the TextBox from pasting
non-numeric entries (the user can paste valid data though) as well as
stopping non-numeric keypresses. By the way, the code is set up for a
TextBox with the default name of TextBox1; change those references to the
name of your actual TextBox.
Rick
For typing digits only in the TextBox
=====================================
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
For typing floating point numbers in the TextBox
=========================================
' Set the maximum number of digits before the
' decimal point in the MaxWhole constant. Set
' the maximum number of digits after the decimal
' point in the MaxDecimal constant.
Dim LastPosition As Long
Private Sub TextBox1_Change()
Static LastText As String
Static SecondTime As Boolean
Const MaxDecimal As Integer = 4
Const MaxWhole As Integer = 2
With TextBox1
If Not SecondTime Then
If .Text Like "*[!0-9.]*" Or _
.Text Like "*.*.*" Or _
.Text Like "*." & String$(1 + MaxDecimal, "#") Or _
.Text Like String$(MaxWhole, "#") & "[!.]*" Then
Beep
SecondTime = True
.Text = LastText
.SelStart = LastPosition
Else
LastText = .Text
End If
End If
End With
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
NOTES
=========================================
Note that you will have check for the Text property containing a single
character consisting of a decimal point since that must be allowed as a
starting character. If you want to allow negative, as well as positive
values, then use this If statement in place of the second If statement in
the Text1_Change event code above:
If .Text Like "*[!0-9.+-]*" Or _
.Text Like "*.*.*" Or _
.Text Like "*." & String$(1 + MaxDecimal, "#") Or _
.Text Like "*" & String$(MaxWhole, "#") & "[!.]*" Or _
.Text Like "?*[+-]*" Then
Note that now you will have to check the Text property for this one to see
if it contains a single plus sign, minus sign or decimal point by themselves
(that is, test if it is a one-character entry consisting of either a plus
sign, minus sign or decimal point).
I guess I should mention that I'm in the US where the decimal point is a
"dot". If your decimal point is some other characters, then make the obvious
substitutions in the If-Then tests above; or you could query the system for
the decimal point character, store it in a variable and concatenate that
into the string values above in place of the decimal point ("dot") that I
show above. In keeping with the non-APIness of this solution, here is what I
use to get the system's decimal point.
DecimalPointSymbol = Format$(0, ".")
--
Rick (MVP - Excel)
Susan said:
Hi, I have a checkbox for "N/A" and a textbox for storing input.
I have the following code checking to make sure the textbox stores a
numeric
input:
Private Sub TextBox2_BeforeUpdate(ByVal Cancel As MSForms.ReturnBoolean)
If IsNumeric(TextBox2.Value) Then
ErrOmTxt = TextBox2.Value
Cancel = False
Else
MsgBox "Errors and Omissions value must be numeric. Please check
and re-enter, or check N/A for no coverage."
TextBox2.Value = ""
TextBox2.SetFocus
Cancel = True
End If
Exit Sub
End Sub
Basically, if the data is valid, store it in a String variable.
Otherwise,
clear the textbox, and allow the user to enter a new value or to check the
checkbox. Checking the N/A checkbox will set Textbox2.Enabled = False
However, in testing--when I type in alpha characters, my msgbox will pop
up,
but I cannot proceed to check the checkbox. I get stuck at this step
until I
close the userform.
Any ideas?
Thanks in advance.