Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase ««123»»

Conversion Fun Expand / Collapse
Author
Message
Posted Friday, August 7, 2009 6:30 AM
SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Wednesday, November 19, 2014 8:00 AM
Points: 827, Visits: 1,693
Essentially, the reason why it doesn't work is because an integer is a subset of the numeric datatypes, and not vice-versa. Things which are numeric are not necessarily integers, while all integers are numeric.
Post #766873
Posted Friday, August 7, 2009 7:10 AM


SSChasing Mays

SSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing Mays

Group: General Forum Members
Last Login: Friday, May 24, 2013 5:20 AM
Points: 660, Visits: 558
I agree with the above post, integer is very specific, in fact forget the odd character, even
select convert(int,'0.0')

will not work.
select convert(decimal(2,1),'0,.0')

will give the error that was supplied as one of the answers to the question.

Interestingly (or not, it is Friday lunch time), money to int will work no worries, rounding to the nearest int, so
select convert(int,convert(money,'0,.0'))

will work fine if you're worried about isnumeric letting you down!


--------
I love deadlines. I like the whooshing sound they make as they fly by. -Douglas Adams
Post #766913
Posted Friday, August 7, 2009 8:38 AM
Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Thursday, July 17, 2014 10:56 AM
Points: 3,924, Visits: 1,607
Christian Buettner (8/7/2009)
If I am not totally wrong, the behaviour is not due to IsNumeric itself, but to the fact that you can cast this value to money or smallmoney.

Try this:

SET NOCOUNT ON
SELECT CONVERT(money ,'1,0.2') A, CONVERT(money ,'1.0,2') B, CONVERT(money ,'1,100,00.2') C

A.......B......C..........
10.2000 1.0200 110000.2000

Now dont ask me why...



Very interesting. Never thought or tried it or say never came across this kind of issue. Not to you Chris, but to some one else who could give better explanation.

My question - Why ?


SQL DBA.
Post #766994
Posted Friday, August 7, 2009 9:19 AM
SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Wednesday, November 19, 2014 8:00 AM
Points: 827, Visits: 1,693
It's just the way that SQL Server deals with Monetary data. It's always got four trailing spaces for decimals, and the decimal symbol (".") is interpreted as being the symbol to indicate that you're dealing with the decimal part of the Money value, while the comma (",") is treated as being part of the non-decimal part.

EG: 1,000 is the same as 1000, while 1.000 is the same as 1, and 1,000.1 is the same as 1000.1
Post #767025
Posted Friday, August 7, 2009 10:07 AM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Monday, November 17, 2014 1:28 PM
Points: 3,189, Visits: 1,271
isnumeric is just evaluating valid characters.

This will produce 1 also

select isnumeric('-$,')




Post #767080
Posted Friday, August 7, 2009 10:17 AM
SSChasing Mays

SSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing Mays

Group: General Forum Members
Last Login: Monday, September 29, 2014 11:11 AM
Points: 660, Visits: 401
ronmoses (8/7/2009)
Dang it, I knew that was the answer and didn't pick it. That seemed like the obvious "otherwise, why would I ask the question?" answer. But no, I had to go and think about it. Stupid me.

Ditto . That said, I would love to hear from the people who thought the answer for a CONVERT(int, {anything}) would be either 0.0 or 0,.0!
Post #767093
Posted Friday, August 7, 2009 11:47 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Tuesday, November 18, 2014 6:12 PM
Points: 367, Visits: 1,080
I'd like to seee the explanation expanded to explain that
select convert(money,'0,.0')

would work, and that is why isNumeric is returning true (i.e. that isnumeric is ignoring the comma because that's what convert does for money).

Try:
select convert(money,'0,,,0,.0,,,0')

Post #767171
Posted Saturday, August 8, 2009 9:12 AM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Wednesday, November 12, 2014 2:56 AM
Points: 2,624, Visits: 581
I encountered this issue a couple of month ago and i solved it with the following udf from ASPFAQ.com [url=http://classicasp.aspfaq.com/general/what-is-wrong-with-isnumeric.html][/url]

CREATE FUNCTION dbo.isReallyNumeric  
(
@num VARCHAR(64)
)
RETURNS BIT
BEGIN
IF LEFT(@num, 1) = '-'
SET @num = SUBSTRING(@num, 2, LEN(@num))

DECLARE @pos TINYINT

SET @pos = 1 + LEN(@num) - CHARINDEX('.', REVERSE(@num))

RETURN CASE
WHEN PATINDEX('%[^0-9.-]%', @num) = 0
AND @num NOT IN ('.', '-', '+', '^')
AND LEN(@num)>0
AND @num NOT LIKE '%-%'
AND
(
((@pos = LEN(@num)+1)
OR @pos = CHARINDEX('.', @num))
)
THEN
1
ELSE
0
END
END
GO

CREATE FUNCTION dbo.isReallyInteger
(
@num VARCHAR(64)
)
RETURNS BIT
BEGIN
IF LEFT(@num, 1) = '-'
SET @num = SUBSTRING(@num, 2, LEN(@num))

RETURN CASE
WHEN PATINDEX('%[^0-9-]%', @num) = 0
AND CHARINDEX('-', @num) <= 1
AND @num NOT IN ('.', '-', '+', '^')
AND LEN(@num)>0
AND @num NOT LIKE '%-%'
THEN
1
ELSE
0
END
END



/Håkan Winther
MCITP:Database Developer 2008
MCTS: SQL Server 2008, Implementation and Maintenance
MCSE: Data Platform
Post #767409
Posted Monday, August 10, 2009 12:59 AM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Tuesday, October 7, 2014 2:56 AM
Points: 2,842, Visits: 3,876
kevin.l.williams (8/7/2009)
isnumeric is just evaluating valid characters.

This will produce 1 also

select isnumeric('-$,')


Hi Kevin,

I think that is not true.
Try
select isnumeric('$$')

for example.
It will evaluate to false, although this character ($) was no issue in your previous example.

The reason why your example is returning true, is probably the fact that it can be cast to (small)money.

Try finding an example that is not convertible to a numeric datatype but that returns true in this function.


Best Regards,
Chris Büttner
Post #767648
Posted Monday, August 10, 2009 5:24 AM
SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Wednesday, November 19, 2014 8:00 AM
Points: 827, Visits: 1,693
Try finding an example that is not convertible to a numeric datatype but that returns true in this function.


That's impossible :P as per the definition of the function, ISNUMERIC only returns true if the input is convertible to one of the numeric data types.
Post #767750
« Prev Topic | Next Topic »

Add to briefcase ««123»»

Permissions Expand / Collapse