Need help utilizing the "Like" function

D

Dreiding

Using Excel 2003, here is example code that doesn't work. What am I doing
wrong?
My isNumeric test returns "True", but there an "A" in my string.
Am I not checking for all the character to be 0 - 9?

Sub Test1()
Debug.Print isNumeric("A00101")
End Sub

Function isNumeric(ByVal sInput As String) As Boolean
If sInput Like "*[0-9]" Then
isNumeric = True
Else
isNumeric = False
End If
End Function

Thanks,
- Pat
 
D

Daryl S

Dreiding -

I am not sure why you aren't using Excel's functions, but here is why your's
isn't working.

You are only testing for the last character to be 0-9. The asterisk will
match to zero or more characters. For example,
Like "*6"
will match for all of these:
abc6
126
6
Z6

That means Like "*[0-9]" will match to any character string ending in a
numeric digit.

If you have a fixed-length string of length 4 and you want them all numeric,
then you could use this:
Like "[0-9][0-9][0-9][0-9]"

If it is variable-length, then you could loop through each character to test
for numerics.
 
B

Bob Phillips

Function isNumeric(ByVal sInput As String) As Boolean
isNumeric = VBA.isNumeric(sInput)
End Function


HTH

Bob
 
R

Rick Rothstein

A short-cut for digits is the # symbol; so, you can check for 4 digits like
this...

If NumberString Like "####" Then MsgBox "NumberString is 4 digits long"

--
Rick (MVP - Excel)


Daryl S said:
Dreiding -

I am not sure why you aren't using Excel's functions, but here is why
your's
isn't working.

You are only testing for the last character to be 0-9. The asterisk will
match to zero or more characters. For example,
Like "*6"
will match for all of these:
abc6
126
6
Z6

That means Like "*[0-9]" will match to any character string ending in a
numeric digit.

If you have a fixed-length string of length 4 and you want them all
numeric,
then you could use this:
Like "[0-9][0-9][0-9][0-9]"

If it is variable-length, then you could loop through each character to
test
for numerics.

--
Daryl S


Dreiding said:
Using Excel 2003, here is example code that doesn't work. What am I
doing
wrong?
My isNumeric test returns "True", but there an "A" in my string.
Am I not checking for all the character to be 0 - 9?

Sub Test1()
Debug.Print isNumeric("A00101")
End Sub

Function isNumeric(ByVal sInput As String) As Boolean
If sInput Like "*[0-9]" Then
isNumeric = True
Else
isNumeric = False
End If
End Function

Thanks,
- Pat
 
R

Rick Rothstein

If you don't want to use the Like comparison (I think it is the better way
to go), you can call out to the Worksheet ISNUMBER function, but I would not
use the VBA IsNumeric function to proof a typed-in value for being a number.
Here is a previous posting of mine explaining why...

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 <> "."
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
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
End Function

--
Rick (MVP - Excel)


Bob Phillips said:
Function isNumeric(ByVal sInput As String) As Boolean
isNumeric = VBA.isNumeric(sInput)
End Function


HTH

Bob

Dreiding said:
Using Excel 2003, here is example code that doesn't work. What am I
doing
wrong?
My isNumeric test returns "True", but there an "A" in my string.
Am I not checking for all the character to be 0 - 9?

Sub Test1()
Debug.Print isNumeric("A00101")
End Sub

Function isNumeric(ByVal sInput As String) As Boolean
If sInput Like "*[0-9]" Then
isNumeric = True
Else
isNumeric = False
End If
End Function

Thanks,
- Pat
 
D

Dana DeLouis

... all the character to be 0 - 9?

Hi. One of many ideas if you want to use 'Like'

Function AllDigits(s)
AllDigits = s Like WorksheetFunction.Rept("[0-9]", Len(s))
End Function

Sub TestIt()
Debug.Print AllDigits("123.45")
Debug.Print AllDigits("678")
End Sub

Returns:
False
True

= = = = = = =
HTH :>)
Dana DeLouis
 
R

Rick Rothstein

Function AllDigits(s)
AllDigits = s Like WorksheetFunction.Rept("[0-9]", Len(s))
End Function

Noting that you can use the # sign in place of [0-9] when searching for
digits, you do not have to call out to the Worksheet to use its REPT
function... VB has the String function that you can use instead.

Function AllDigits(s)
AllDigits = s Like String(Len(s), "#")
End Function

If, however, you are more used to using [0-9] instead of the # sign and want
to continue doing so, you can still do this using native VB functions
only...

Function AllDigits(s)
AllDigits = s Like Replace(String(Len(s), "x"), "x", "[0-9]")
End Function

where you can use any character in place of the "x" characters I used.
Because of this, we can simplify this code by using a space instead of the
"x" and then noting that VB has a Space function which returns the number of
space specified in its argument...

Function AllDigits(s)
AllDigits = s Like Replace(Space(Len(s)), " ", "[0-9]")
End Function

--
Rick (MVP - Excel)


Dana DeLouis said:
... all the character to be 0 - 9?

Hi. One of many ideas if you want to use 'Like'

Function AllDigits(s)
AllDigits = s Like WorksheetFunction.Rept("[0-9]", Len(s))
End Function

Sub TestIt()
Debug.Print AllDigits("123.45")
Debug.Print AllDigits("678")
End Sub

Returns:
False
True

= = = = = = =
HTH :>)
Dana DeLouis



Using Excel 2003, here is example code that doesn't work. What am I
doing
wrong?
My isNumeric test returns "True", but there an "A" in my string.
Am I not checking for all the character to be 0 - 9?

Sub Test1()
Debug.Print isNumeric("A00101")
End Sub

Function isNumeric(ByVal sInput As String) As Boolean
If sInput Like "*[0-9]" Then
isNumeric = True
Else
isNumeric = False
End If
End Function

Thanks,
- Pat
 
D

Dana DeLouis

Function AllDigits(s)
AllDigits = s Like String(Len(s), "#")
End Function

Thanks Rick. I totally forgot about that. :>~
Thanks for the catch.

Dana DeLouis



Function AllDigits(s)
AllDigits = s Like WorksheetFunction.Rept("[0-9]", Len(s))
End Function

Noting that you can use the # sign in place of [0-9] when searching for
digits, you do not have to call out to the Worksheet to use its REPT
function... VB has the String function that you can use instead.

Function AllDigits(s)
AllDigits = s Like String(Len(s), "#")
End Function

If, however, you are more used to using [0-9] instead of the # sign and
want to continue doing so, you can still do this using native VB
functions only...

Function AllDigits(s)
AllDigits = s Like Replace(String(Len(s), "x"), "x", "[0-9]")
End Function

where you can use any character in place of the "x" characters I used.
Because of this, we can simplify this code by using a space instead of
the "x" and then noting that VB has a Space function which returns the
number of space specified in its argument...

Function AllDigits(s)
AllDigits = s Like Replace(Space(Len(s)), " ", "[0-9]")
End Function
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top