Numbers and Letters

N

Noob McKnownowt

Hey guys just a quick question, is there any way of getting a piece of code
to tell the difference between a number and a letter, for example

if cell.value = cell.value.text (a letter or group of letters) then
copy info into col a
elseif cell.value = cell.value.number (a number or group of numbers) then
copy info into col b
end if

I am not asking for any specific code to complete a task, just if any of you
know how to get your code to distinguish between a number or letter without
stating either of them specifically.

Any assistance would be greatly apprieciated.

The Noob
 
B

Barb Reinhardt

I'd do something like this

if IsNumeric(Cell.value) then
....do your thing
else

end if
 
N

Noob McKnownowt

Thank you very much, you're a star.

The Noob.

Barb Reinhardt said:
I'd do something like this

if IsNumeric(Cell.value) then
....do your thing
else

end if
--
HTH,
Barb Reinhardt

If this post was helpful to you, please click YES below.
 
R

Rick Rothstein

There are some potential problems with using IsNumeric which you should be
aware of.

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

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
 
R

Rick Rothstein

Just to follow up, I thought the following might be of some help...

If Len(CellValue) > 0 And CellValue Like "[.]" Then
If Not CellValue Like "*[!a-zA-Z]*" Then
MsgBox "Cell value contains only letters"
ElseIf Not CellValue Like "*[!0-9]*" Then
MsgBox "Cell value contains only digits"
ElseIf Not Value Like "*[!0-9.]*" And Not Value Like "*.*.*" _
And Value <> "." And Value <> vbNullString Then
MsgBox "Cell value contains a floating point number"
Else
MsgBox "Cell value is not a number or all letters"
End If
Else
MsgBox "Cell value is not a number or all letters"
End If

Note that if your cell contains punctuation marks (excluding a single
decimal point in a floating point number), then it will not meet any of the
tests and the Else condition will report it as not being a number or all
letters. If you need to allow some punctuation marks, place them in front of
the right-square brackets <]> for the first If..Then test and for the
appropriate inner If..Then test as well. And if one of those punctuation
marks is a dash, make sure it is the last character in the list (that is, it
comes immediately before the right-square bracket). Of course, you can
substitute any of your own code for the Message Boxes.

--
Rick (MVP - Excel)


Rick Rothstein said:
There are some potential problems with using IsNumeric which you should be
aware of.

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

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

--
Rick (MVP - Excel)


Noob McKnownowt said:
Thank you very much, you're a star.

The Noob.
 
B

Barb Reinhardt

Thanks Rick. I've learned more today. :)

Barb Reinhardt

Rick Rothstein said:
Just to follow up, I thought the following might be of some help...

If Len(CellValue) > 0 And CellValue Like "[.]" Then
If Not CellValue Like "*[!a-zA-Z]*" Then
MsgBox "Cell value contains only letters"
ElseIf Not CellValue Like "*[!0-9]*" Then
MsgBox "Cell value contains only digits"
ElseIf Not Value Like "*[!0-9.]*" And Not Value Like "*.*.*" _
And Value <> "." And Value <> vbNullString Then
MsgBox "Cell value contains a floating point number"
Else
MsgBox "Cell value is not a number or all letters"
End If
Else
MsgBox "Cell value is not a number or all letters"
End If

Note that if your cell contains punctuation marks (excluding a single
decimal point in a floating point number), then it will not meet any of the
tests and the Else condition will report it as not being a number or all
letters. If you need to allow some punctuation marks, place them in front of
the right-square brackets <]> for the first If..Then test and for the
appropriate inner If..Then test as well. And if one of those punctuation
marks is a dash, make sure it is the last character in the list (that is, it
comes immediately before the right-square bracket). Of course, you can
substitute any of your own code for the Message Boxes.

--
Rick (MVP - Excel)


Rick Rothstein said:
There are some potential problems with using IsNumeric which you should be
aware of.

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

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

--
Rick (MVP - Excel)


Noob McKnownowt said:
Thank you very much, you're a star.

The Noob.

:

I'd do something like this

if IsNumeric(Cell.value) then
....do your thing
else

end if
--
HTH,
Barb Reinhardt

If this post was helpful to you, please click YES below.



:

Hey guys just a quick question, is there any way of getting a piece of
code
to tell the difference between a number and a letter, for example

if cell.value = cell.value.text (a letter or group of letters) then
copy info into col a
elseif cell.value = cell.value.number (a number or group of numbers)
then
copy info into col b
end if

I am not asking for any specific code to complete a task, just if any
of you
know how to get your code to distinguish between a number or letter
without
stating either of them specifically.

Any assistance would be greatly apprieciated.

The Noob
 
D

Dave Peterson

application.isnumber(cell.value)
is much more stringent than VBA's
isnumeric(cell.value)

The text string '1234 will return False with excel's =isnumber() worksheet
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