Isnumeric function - ISNUMERIC('1E2')

  • I have a sql statement converting varchar to bigint. Below are what I got.

    select ISNUMERIC('1E2')

    returns

    1

    select CAST('1E2' as bigint)

    returns

    Msg 8114, Level 16, State 5, Line 3

    Error converting data type varchar to bigint.

    So I have to use the following code to test whether a varchar can be converted to a bigint.

    where ISNUMERIC(TextID)=1 and charindex('E',TextID)=0; -- the requirement is that "E" is not supposed to be in the TextID

    if "1E2" was a valid ID value, then I would have to write a separate code to convert 1E2 to 100.

    Is there a better way to handle numbers like '1E2'?

  • To check for anything other than only digits (0 thru 9), use:

    NOT LIKE '%[^0-9]%'

    for example:

    SELECT

    TextID,

    CASE WHEN TextID NOT LIKE '%[^0-9]%' THEN 'OK' ELSE 'Bad' END

    FROM (

    SELECT '1E2' AS TextID UNION ALL

    SELECT '07809475902174790857' UNION ALL

    SELECT '80780976897.6'

    ) AS test_data

    SQL DBA,SQL Server MVP(07, 08, 09) "It's a dog-eat-dog world, and I'm wearing Milk-Bone underwear." "Norm", on "Cheers". Also from "Cheers", from "Carla": "You need to know 3 things about Tortelli men: Tortelli men draw women like flies; Tortelli men treat women like flies; Tortelli men's brains are in their flies".

  • Take a look at this article. It shows what's happening and how to get an all-digits validation.

    http://www.sqlservercentral.com/articles/ISNUMERIC()/71512/

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2
  • This is a possible option based on Scott's post. You might need to use additional validations and things can get really complex really quickly.

    SELECT

    TextID,

    CASE WHEN TextID NOT LIKE '%[^0-9]%' THEN CAST( TextID as bigint)

    ELSE CAST( CAST( TextID as float) as bigint) END

    FROM (

    SELECT '1E2' AS TextID UNION ALL

    SELECT '07809475902174790857' UNION ALL

    SELECT '80780976897.6'

    ) AS test_data

    The best option is to correct this from the source.

    EDIT: Forgot to include the code. :hehe:

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2
  • Thanks for all the help.

    It works.

    TextID NOT LIKE '%[^0-9]%'

  • Remember ISNUMERIC simply tells you that a value may be converted to a numeric value, it just doesn't tell you what numeric value. Using your example of 1E2:

    select CAST('1E2' as bigint);

    --Msg 8114, Level 16, State 5, Line 1

    --Error converting data type varchar to bigint.

    go

    select CAST('1E2' as float);

    --Returns: 100

    go

  • seaport (10/27/2014)


    Thanks for all the help.

    It works.

    TextID NOT LIKE '%[^0-9]%'

    As long as you don't have any decimal points or negative numbers.....

    ----------------------------------------------------------------------------------
    Your lack of planning does not constitute an emergency on my part...unless you're my manager...or a director and above...or a really loud-spoken end-user..All right - what was my emergency again?

Viewing 7 posts - 1 through 6 (of 6 total)

You must be logged in to reply to this topic. Login to reply