View Single Post
  #4   Report Post  
Posted to microsoft.public.excel.programming
Rick Rothstein \(MVP - VB\)[_2429_] Rick Rothstein \(MVP - VB\)[_2429_] is offline
external usenet poster
 
Posts: 1
Default Finding a string of 7 numbers in cell contents

Your use of this...

If IsNumeric(arr2(c)) Then


could false hit in any number of ways (see my standard warning about
IsNumeric after my signature); for example, one way being if this 123.456
came before this 1234567 in the text. I would do the test this way...

If arr2(c) Like "#######" Then

Rick

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



"RB Smissaert" wrote in message
...
Try something like this:

Sub test()

Dim i As Long
Dim c As Long
Dim n As Long
Dim arr
Dim arr2
Dim arr3

'test data range
arr = Range(Cells(1), Cells(5, 1))

ReDim arr3(1 To UBound(arr), 1 To 1)

For i = 1 To UBound(arr)
arr2 = Split(arr(i, 1), Chr(32))
For c = 0 To UBound(arr2)
If Len(arr2(c)) = 7 Then
If IsNumeric(arr2(c)) Then
n = n + 1
arr3(n, 1) = arr2(c)
End If
End If
Next c
Next i

Range(Cells(3), Cells(UBound(arr), 3)) = arr3

End Sub


RBS


"anon" wrote in message
...
Hi,

I have a list of cells, each containing address, tel. no. and customer
ID for a specific customer.

I'm looking to find the customer ID from a each cell and copy to
another cell using vb.

The customer ID could appear at the beginning, middle or end of the
cell contents, however is always 7 digits long with a space at each
side of it (unless it is the first part of the cell contents in which
case there would be no space at the beginning). The complexity is that
the cell also contains telephone numbers, however these are longer
than 7 digits.

Your help / ideas on how I could start tackling this would be much
appreciated. Thanks,