Results 1 to 4 of 4

Thread: Thinking About Using VBA's IsNumeric Function? Read this first.

Threaded View

Previous Post Previous Post   Next Post Next Post
  1. #1
    Forum Guru Rick Rothstein's Avatar
    Join Date
    Feb 2012
    Posts
    659
    Rep Power
    13

    Thinking About Using VBA's IsNumeric Function? Read this first.

    I have posted the following many times over the last 10 years or so in responding to old newsgroup and current forum questions. I decided to post it here for all to see.

    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,,D56$)$$$$$$$")
    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
    Last edited by Rick Rothstein; 08-15-2021 at 08:04 AM.

Similar Threads

  1. UDF (user defined function) replacement for Excel's DATEDIF function
    By Rick Rothstein in forum Rick Rothstein's Corner
    Replies: 21
    Last Post: 03-07-2015, 09:47 PM
  2. Excel 2010 hide Read Only messages
    By DAUPVVO in forum Excel Help
    Replies: 1
    Last Post: 03-19-2014, 07:51 AM
  3. How To Make A Workbook Read-Only
    By Transformer in forum Tips, Tricks & Downloads (No Questions)
    Replies: 0
    Last Post: 07-16-2013, 07:28 AM
  4. Read/write very large xl2007 files
    By Rasm in forum Excel Help
    Replies: 3
    Last Post: 04-07-2012, 05:28 AM
  5. Replies: 2
    Last Post: 12-12-2011, 01:51 PM

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •