Odd Results from IsNumeric VBA funtion

JJC1965

New Member
Joined
Mar 29, 2012
Messages
28
I have been working on a project to copy rows of Data from one worksheet to another. I have it working well except for one problem. I do not want to copy and paste blank row. If have added the following code to loop through the rows of my range of data and only copy rows with data in a certain cell column:

For Each Row In SelectedRange.Rows
If IsNumeric(Row.Cells(i, 8)) Then
Row.Copy

"i' is a variable that numbers each row, column 8 is a calculated currency field, an "extended price" in the original worksheet. I have used a message box to see what the if clause is returning and it returns "True" on some cells with not value and some empty cells and returns "false" on some cells with a value. Is there a better functions or way to sort this data?
 

Excel Facts

Copy PDF to Excel
Select data in PDF. Paste to Microsoft Word. Copy from Word and paste to Excel.
I have this "thing" against the IsNumeric function, so many years ago (back in my volunteering days for the compiled version of VB) I used to post this message to the then newsgroups that covered user questions before forums became popular, I think it kind of explains the "why" of it...

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

Code:
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 307 -- 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 (the code is simple enough that it can be pulled from the function "housing" and used directly inside your own code):

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

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

Code:
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
 
Upvote 0
Hi Rick,

Just curious, does Worksheetfunction.Isnumber share the same flaws, or does it have different ones.
 
Upvote 0
Rick,

Thanks for the functions, but unfortunately I am still getting the odd results. Skipping some rows and coping some rows that are blank. Here is more of my code:

With shtData
i = 1
For Each Row In SelectedRange.Rows
If IsDigitsOnly(Row.Cells(i, 7)) Then
Row.Copy
shtNew.Range("A" & (2 + i), "I" & (2 + i)).PasteSpecial xlPasteValues
End If
i = i + 1
Next Row
End With

Is there something else I have missed?
 
Upvote 0
Rick,

Thanks for the functions, but unfortunately I am still getting the odd results. Skipping some rows and coping some rows that are blank. Here is more of my code:

With shtData
i = 1
For Each Row In SelectedRange.Rows
If IsDigitsOnly(Row.Cells(i, 7)) Then
Row.Copy
shtNew.Range("A" & (2 + i), "I" & (2 + i)).PasteSpecial xlPasteValues
End If
i = i + 1
Next Row
End With

Is there something else I have missed?

I think the problem has to do with the line of code I highlighted in red. Every loop, you look i rows below the row I think you want to look at... my guess is you would want to test the cell in Column G on the current row, not the row i rows down. Try changing the highlighted line of code to tis and see if it makes a difference...

Code:
If IsDigitsOnly(Row.Cells(, 7)) Then
All I did was to remove the i but leave the comma.
 
Upvote 0
That has taken care of of the skipping row, but I am still having rowe coping that are blank. I don't want to copy the blank row, do I need to add an "Else" clause to my If-then to move over the blank rows?
 
Upvote 0

Forum statistics

Threads
1,224,847
Messages
6,181,313
Members
453,032
Latest member
Pauh

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top