Results 1 to 7 of 7

isString ? or IsNumber ? in VBA...

This is a discussion on isString ? or IsNumber ? in VBA... within the Excel Questions forums, part of the Question Forums category; If I have a scalar, then is there a function I can call (or write) to determine if it is ...

  1. #1
    Board Regular Terry_Orange's Avatar
    Join Date
    Jul 2002
    Posts
    133

    Default

    If I have a scalar, then is there a function I can call (or write) to determine if it is a string or a number.

    for example a string I would parse, but an integer I would use in a statistical test.

    Can anyone offer a solution ?
    Thanks
    TO.

  2. #2
    MrExcel MVP Richie(UK)'s Avatar
    Join Date
    May 2002
    Location
    UK
    Posts
    3,330

    Default

    Hi Terry,

    VBA has a 'IsNumeric' function. See below for the VBE Help examples. Is this what you are after?

    This example uses the IsNumeric function to determine if a variable can be evaluated as a number.

    Dim MyVar, MyCheck
    MyVar = "53" ' Assign value.
    MyCheck = IsNumeric(MyVar) ' Returns True.

    MyVar = "459.95" ' Assign value.
    MyCheck = IsNumeric(MyVar) ' Returns True.

    MyVar = "45 Help" ' Assign value.
    MyCheck = IsNumeric(MyVar) ' Returns False.
    Richie

  3. #3
    Board Regular Terry_Orange's Avatar
    Join Date
    Jul 2002
    Posts
    133

    Default


    /@

    ___>
    (__O)
    (____@)
    (____@)
    (__o)_


    Exactly what I was after. Thank you.
    VERY much appreciated.
    T.


  4. #4
    New Member
    Join Date
    Jul 2011
    Posts
    3

    Default Re: isString ? or IsNumber ? in VBA...

    WATCH OUT!
    The solution is not water tight!

    MyVar = "459,95" ' Assign value.
    MyCheck = IsNumeric(MyVar) ' Returns True.
    But if you calculatet with the assumed number e.g.
    MYResult = 1* MyVar then you get a strange result: 45995!!!!

  5. #5
    New Member
    Join Date
    Jul 2011
    Posts
    3

    Default Re: isString ? or IsNumber ? in VBA...

    I came up with the following function.
    It will give FALSE for values like:
    "", "Four", "2,3", "Now()"
    It will give TRUE for values like:
    "1", "-0", "2.3" "-2.300", "3/4", "1.2E-8"

    If the regional settings are set for countries that have a decimal valueto be "," then "2,3 will be TRUE and "2.3" will be false.

    Function fncIsNumber(varInput As Variant) As Boolean
    'Checks if the value in the variant is a number. Note this is NOT the case for the IsNumeric function.
    'Isnumeric("3,4") returns TRUE and will see 3,4 as 34, while fncIsNumber("3,4") returns False!
    'Values like "1.2E-8" are also validates a a valid number.
    Dim strDecimalSeparator As String

    strDecimalSeparator = Mid(Trim(CStr(1 / 2)), 2, 1) 'Returns ',' or '.' depending on regional settings
    If strDecimalSeparator = "." Then
    strDecimalSeparator = "," 'Switch to the other decimal separator
    Else
    strDecimalSeparator = "." 'Switch to the other decimal separator
    End If

    fncIsNumber = False
    If IsNumeric(varInput) Then
    If InStr(1, varInput, strDecimalSeparator) = 0 Then fncIsNumber = True
    End If
    End Function

  6. #6
    MrExcel MVP Rick Rothstein's Avatar
    Join Date
    Apr 2011
    Location
    New Jersey, USA
    Posts
    14,815

    Default Re: isString ? or IsNumber ? in VBA...

    Quote Originally Posted by mdalamers View Post
    WATCH OUT!
    The solution is not water tight!

    MyVar = "459,95" ' Assign value.
    MyCheck = IsNumeric(MyVar) ' Returns True.
    But if you calculatet with the assumed number e.g.
    MYResult = 1* MyVar then you get a strange result: 45995!!!!
    Here is a message that I originally started posting many years ago in the compiled VB newsgroups and, when applicable, repeated in Excel newsgroups/forums...

    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 (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

  7. #7
    New Member
    Join Date
    Jul 2011
    Posts
    3

    Default Re: isString ? or IsNumber ? in VBA...

    Hi Rick,

    This was very helpful and educational.
    Thank you!

    ML.

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

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


DMCA.com