isnumeric issue

  • When I am using the isnumeric function and passing the character value('2d3') its retrrning it as number. Below is the code.

    DECLARE @profile varchar(200)

    IF ISNUMERIC('2d3')=1

    SET @profile = 'NUMBER'

    ELSE

    SET @profile = 'CHAR'

    SELECT @profile

    Can any of you please tell me why its behaving like this. It should return as CHAR, but returning as NUMBER.

    Thanks in Advance

    Regards,

    Naveen

  • becasue '2d3' = 2000 as a valid float value so ISNUMERIC will return 1

    SELECT CAST('2d3' AS float)

  • but when I tried to use the below query

    IF ISNUMERIC('$123432345')=1

    SET @profile = 'NUMBER'

    ELSE

    SET @profile = 'CHAR'

    SELECT @profile

    it is also returning number even though its having $ character.

    Please help

  • This is because you are passing in a valid money data type so this will return true

    from BOL

    ISNUMERIC returns 1 when the input expression evaluates to a valid integer, floating point number, money or decimal type; otherwise it returns 0. A return value of 1 indicates that expression can be converted to at least one of the numeric types.

    I consider ISNUMERIC to be a slightly misleading and possbile dangerous function to use when not fully understood. It is different than a function that will tell you wheter a value contains only numbers and nothing else.

    A better what to go about this could be to use PATINDEX, this will only return true where the column contains only Numbers

    DECLARE @profile CHAR(10)

    IF PATINDEX('%[^0-9]%', '£123432345') = 0

    SET @profile = 'NUMBER'

    ELSE

    SET @profile = 'CHAR'

    SELECT @profile

    Note: this is not a pefect example as it will dissallow numbers with a decimal place (.) however you can modify the PATINDEX to meet your business requirements

  • Thanks Steve for the solution provided. It has worked as expected.

    Thanks again

  • Steve i made an ITVF based on your example, but i added a bit more to it;

    i was thinking if i allow periods in the data, i need to check for more than one period...so 123.45 would be valud, but 192.168.1.100 would not;

    would you agree with that logic?

    here's what i put together:

    CREATE FUNCTION IsNumeric2(@str varchar(20))

    RETURNS int

    WITH SCHEMABINDING

    AS

    BEGIN

    declare @results int

    SELECT @results = CASE

    WHEN (PATINDEX('%[^0-9,.]%', @STR) = 0) AND (LEN(@str) - LEN(REPLACE(@str,'.','')) <= 1)

    THEN 1

    ELSE 0

    END

    return @results

    END --FUNCTION

    GO

    CREATE FUNCTION IsNumeric3(@str varchar(20))

    RETURNS TABLE

    WITH SCHEMABINDING

    AS

    RETURN(SELECT CASE

    WHEN (PATINDEX('%[^0-9,.]%', @STR) = 0) AND (LEN(@str) - LEN(REPLACE(@str,'.','')) <= 1)

    THEN 1

    ELSE 0

    END As boolNumeric

    ) --END FUNCTION

    Lowell


    --help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

  • That looks good and definately improves on the logic, nice work..

    I guess in the end it depends on the business rules that the OP are running under would determine what is a 'number' or not.

  • Lowell (6/16/2010)


    Steve i made an ITVF based on your example, but i added a bit more to it;

    i was thinking if i allow periods in the data, i need to check for more than one period...so 123.45 would be valud, but 192.168.1.100 would not;

    would you agree with that logic?

    Wouldn't just using ISNUMERIC as well as the PATINDEX work in that case? ISNUMERIC will return false for any number with more than one decimal point, because it can't convert that to a valid number!

  • Make sure to read this

    http://www.sqlservercentral.com/articles/IsNumeric/71512/


    Madhivanan

    Failing to plan is Planning to fail

Viewing 9 posts - 1 through 8 (of 8 total)

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