Bullet-proof test for numeric data

JenniferMurphy

Well-known Member
Joined
Jul 23, 2011
Messages
2,687
Office Version
  1. 365
Platform
  1. Windows
A UDF I was working on failed when passed data from a cell that was "empty". To get it to work, I had to change the If statement to this:

Code:
If IsNumeric(parm) And Not IsEmpty(Parm) Then . . .

Is this the correct (& optimal) statement?
 

Excel Facts

Formula for Yesterday
Name Manager, New Name. Yesterday =TODAY()-1. OK. Then, use =YESTERDAY in any cell. Tomorrow could be =TODAY()+1.
IsEmpty only returns meaningful information for Variants (initialized or not). Could you please elaborate on the "cell that was "empty""?
 
Upvote 0
IsNumeric is not a foolproof way to test whether a text string is a number or not.

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
what about something like this?
Code:
Function IsNumber(ByVal Value As String) As Boolean
    IsNumber = Len(Value) And Value = Value * 1
End Function
I can see it not handling strings (that are treated by Excel as strings though people might want them to be numbers - so things like "(10)" entered as text). But for arguments that are numbers it seems OK?
 
Upvote 0
what about something like this?
Code:
Function IsNumber(ByVal Value As String) As Boolean
    IsNumber = Len(Value) And Value = Value * 1
End Function
I can see it not handling strings (that are treated by Excel as strings though people might want them to be numbers - so things like "(10)" entered as text). But for arguments that are numbers it seems OK?
The OP asked for a "bullet-proof" test... even if you put in the error trap necessary to handle pure text arguments, it will report True for values like "1e23", "&HEAD", "1,,2,,3", among others.
 
Upvote 0
IsEmpty only returns meaningful information for Variants (initialized or not). Could you please elaborate on the "cell that was "empty""?

The case that triggered the problem was a UDF that was processing data in a range of cells. The relevant snippets are:
Code:
Public Function WtdRtg(pRtgWts As Range, . . . ) As Variant
 . . .
Dim iCol As Long
For iCol = RngColBeg To RngColEnd
  WgtI = pRtgWts(1, iCol)             'Get the next weight
  If IsNumeric(WgtI) And Not IsEmpty(WgtI) Then
     . . .
 
Upvote 0
IsNumeric is not a foolproof way to test whether a text string is a number or not.

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.

. . . snip

Yikes!!! :eeek: I had no idea this could be so complicated.

Since this is for my personal use, I am inclined to ignore some of the more exotic cases that I would never use. Of course, there always fat-fingered typos that could look like one of your cases and that would get past my checker. I would rather catch a few valid numbers entered with non-standard (for me) notation than let any errors get through and corrupt the results unbeknownst to me.

Thanks so much for this excruciatingly detailed analysis.
 
Upvote 0
what about something like this?
Code:
Function IsNumber(ByVal Value As String) As Boolean
    IsNumber = Len(Value) And Value = Value * 1
End Function
I can see it not handling strings (that are treated by Excel as strings though people might want them to be numbers - so things like "(10)" entered as text). But for arguments that are numbers it seems OK?

At first glance, this looked like a pretty good solution. Then I read Rick's response. Now I don't think it will work for my needs.
 
Upvote 0
The case that triggered the problem was a UDF that was processing data in a range of cells. The relevant snippets are:
Code:
Public Function WtdRtg(pRtgWts As Range, . . . ) As Variant
 . . .
Dim iCol As Long
For iCol = RngColBeg To RngColEnd
  WgtI = pRtgWts(1, iCol)             'Get the next weight
  If IsNumeric(WgtI) And Not IsEmpty(WgtI) Then
     . . .
Perhaps
Code:
Public Function WtdRtg(pRtgWts As Range,...) As Variant
    ...
    Dim iCol As Long
    For iCol = RngColBeg To RngColEnd
        If (pRtgWts(1, iCol) <> "") And IsNumeric(Evaluate("--" & pRtgWts(1, iCol))) Then
            WgtI = pRtgWts(1, iCol)     'Get the next weight
            ...
 
Upvote 0
The OP asked for a "bullet-proof" test... even if you put in the error trap necessary to handle pure text arguments, it will report True for values like "1e23", "&HEAD", "1,,2,,3", among others.

Thanks, Rick. And for your erudite comments earlier

In my Excel,

1e23 becomes 1E23 when I type it in & that returns TRUE. A good result.

entering with double quotes as "1e23" returns FALSE. Depends on what is wanted: as it is text being entered, I'd be happy with FALSE

&HEAD returns FALSE for me. And you get TRUE
1,,2,,3 also returns FALSE. And you get TRUE

Something strange
 
Upvote 0

Forum statistics

Threads
1,223,894
Messages
6,175,254
Members
452,624
Latest member
gregg777

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