Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


isnumeric issue


isnumeric issue

Author
Message
ekknaveen
ekknaveen
SSC Veteran
SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)

Group: General Forum Members
Points: 243 Visits: 343
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
steveb.
steveb.
Hall of Fame
Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)

Group: General Forum Members
Points: 3896 Visits: 7195
becasue '2d3' = 2000 as a valid float value so ISNUMERIC will return 1


SELECT CAST('2d3' AS float)


ekknaveen
ekknaveen
SSC Veteran
SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)

Group: General Forum Members
Points: 243 Visits: 343
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
steveb.
steveb.
Hall of Fame
Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)

Group: General Forum Members
Points: 3896 Visits: 7195
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
ekknaveen
ekknaveen
SSC Veteran
SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)

Group: General Forum Members
Points: 243 Visits: 343
Thanks Steve for the solution provided. It has worked as expected.

Thanks again
Lowell
Lowell
SSC-Insane
SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)

Group: General Forum Members
Points: 24946 Visits: 39743
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!

steveb.
steveb.
Hall of Fame
Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)

Group: General Forum Members
Points: 3896 Visits: 7195
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.
paul.knibbs
paul.knibbs
SSCrazy
SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)

Group: General Forum Members
Points: 2339 Visits: 6231
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!
Madhivanan-208264
Madhivanan-208264
Mr or Mrs. 500
Mr or Mrs. 500 (543 reputation)Mr or Mrs. 500 (543 reputation)Mr or Mrs. 500 (543 reputation)Mr or Mrs. 500 (543 reputation)Mr or Mrs. 500 (543 reputation)Mr or Mrs. 500 (543 reputation)Mr or Mrs. 500 (543 reputation)Mr or Mrs. 500 (543 reputation)

Group: General Forum Members
Points: 543 Visits: 476
Make sure to read this
http://www.sqlservercentral.com/articles/IsNumeric/71512/



Madhivanan

Failing to plan is Planning to fail
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search