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 «««12345»»»

ISNUMERIC Expand / Collapse
Author
Message
Posted Monday, September 27, 2010 4:16 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 12:02 PM
Points: 13,280, Visits: 10,154
Hugo Kornelis (9/27/2010)
da-zero (9/27/2010)

So 1+1 should still be rejected in your opinion.

It is. ISNUMERIC('1+1') returns 0. And that makes sense, because '1+1' does not convert to any of the numerical data types.


Dammit. I knew I should've test it before I made such a statement.
My point was that although + is not a number, the result of the expression 1+1 is a number. So I meant 1+1 as an expression, not '1+1' as a string.




How to post forum questions.
Need an answer? No, you need a question.
What’s the deal with Excel & SSIS?

Member of LinkedIn. My blog at LessThanDot.

MCSA SQL Server 2012 - MCSE Business Intelligence
Post #993537
Posted Monday, September 27, 2010 4:19 AM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Today @ 8:38 AM
Points: 1,713, Visits: 6,249
Hugo Kornelis (9/27/2010)
That all being said, I completely fail to see the acutal use of a function that tells me that a string value "is either a number or its not". What good is it to know that a value is a number if I can still not convert it to a numerical data type without the risk of getting a runtime error? You may see a good use for such a function, but I don't.


The only possible use I can think of is as a preliminary check in a user defined implementation:
if IsNumeric(@value)
begin
--It might be numeric so now do some proper validation
-- (which is probably more resource-expensive than the built-in function
end
else
--Definitely not numeric


But that's just trying to find a use for the sake of it, I don't think I'd bother in real life!
Post #993540
Posted Monday, September 27, 2010 4:22 AM
UDP Broadcaster

UDP BroadcasterUDP BroadcasterUDP BroadcasterUDP BroadcasterUDP BroadcasterUDP BroadcasterUDP BroadcasterUDP Broadcaster

Group: General Forum Members
Last Login: Sunday, June 29, 2014 11:26 PM
Points: 1,481, Visits: 1,960
Hugo Kornelis (9/27/2010)
tommyh (9/27/2010)
I dont agree with your arguments either. A string is either a number or its not. Not depending on what you try and convert it to. It should be one or the other.

If that's your point of view, then you should be happy with the current implementation of ISNUMERIC. "2e1" is a valid number.

I already said that all programming languages I have worked with recognise 1e2 as a floating point representation for 20 (1 x 102). I had at that time not yet verified your assertion that ".NET doesnt do this. Old VB6 does...". I have now. Using Visual Studio 2005, I opened a VB.Net project, edited a line to include the numeric constant "1e3", and I Visual Studio automatically changed it to "1000.0". I then tried the same with "1.23e-15", and VisualStudio changed that to "1.23E-15". Both versions could be compiled and executed.

I then tried the same with a C# project. This time, the code was not changed, but it still compiled and executed without problems.

So, I don't know who made you believe that .NET "doesnt do this" - but if I were you, I'd start double checking all other information from the same source, for it is apparently not the most reliable authority on .NET.


That all being said, I completely fail to see the acutal use of a function that tells me that a string value "is either a number or its not". What good is it to know that a value is a number if I can still not convert it to a numerical data type without the risk of getting a runtime error? You may see a good use for such a function, but I don't.



decimal.TryParse("2e1",out d) gives a False. Int version does the same. So right back at you.

/T
Post #993543
Posted Monday, September 27, 2010 4:41 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 9:23 AM
Points: 5,925, Visits: 8,173
tommyh (9/27/2010)
Hugo Kornelis (9/27/2010)
tommyh (9/27/2010)
I dont agree with your arguments either. A string is either a number or its not. Not depending on what you try and convert it to. It should be one or the other.

If that's your point of view, then you should be happy with the current implementation of ISNUMERIC. "2e1" is a valid number.

I already said that all programming languages I have worked with recognise 1e2 as a floating point representation for 20 (1 x 102). I had at that time not yet verified your assertion that ".NET doesnt do this. Old VB6 does...". I have now. Using Visual Studio 2005, I opened a VB.Net project, edited a line to include the numeric constant "1e3", and I Visual Studio automatically changed it to "1000.0". I then tried the same with "1.23e-15", and VisualStudio changed that to "1.23E-15". Both versions could be compiled and executed.

I then tried the same with a C# project. This time, the code was not changed, but it still compiled and executed without problems.

So, I don't know who made you believe that .NET "doesnt do this" - but if I were you, I'd start double checking all other information from the same source, for it is apparently not the most reliable authority on .NET.


That all being said, I completely fail to see the acutal use of a function that tells me that a string value "is either a number or its not". What good is it to know that a value is a number if I can still not convert it to a numerical data type without the risk of getting a runtime error? You may see a good use for such a function, but I don't.



decimal.TryParse("2e1",out d) gives a False. Int version does the same. So right back at you.

/T

Correct. And double.TryParse("2e1,out d) gives a True and sets d to 20.0. Exactly as expected.
Remember, I was the guy who said that ISNUMERIC() sucks because it doesn't differentiate between data types, and you were the one claiming that a string is either numeric or it isnt. Yet, the .Net code you use to support your point uses different methods for each data type - exactly what I want in SQL Server, and what you say is irrelevant.



Hugo Kornelis, SQL Server MVP
Visit my SQL Server blog: http://sqlblog.com/blogs/hugo_kornelis
Post #993549
Posted Monday, September 27, 2010 6:06 AM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Today @ 10:57 AM
Points: 1,297, Visits: 1,656
foxxo (9/27/2010)
Does the CTE with UNION ALL increment i? It needs to increment in each column? I no comprehende


Yes. This technique is called a recursive CTE. It's a way of generating a sequence of rows without using a tally table. See http://msdn.microsoft.com/en-us/library/ms186243.aspx for more details.
Post #993581
Posted Monday, September 27, 2010 6:27 AM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Today @ 10:57 AM
Points: 1,297, Visits: 1,656
Thanks for the good discussion. For the record, I agree with Hugo -- ISNUMERIC doesn't give you very good information because it's test is overly broad.

For example,
\-    ,,.,

succeeds in ISNUMERIC() because that converts to a MONEY value of 0.

If you want to see some of the other odd things that are considered numeric by this function, try this:

declare @limit int
set @limit = 4

;with l as (
select 32 as i, char(32) as s, isnumeric(char(32)) as n
union all
select i+1, char(i+1), isnumeric(char(i+1)) from l where i < 127
),
m as (
select cast(l.s as varchar(max)) as ms, isnumeric(l.s) as mn
from l
where ISNUMERIC(l.s) = 1
union all
select ms + cast(l.s as varchar(max)), ISNUMERIC(ms + cast(l.s as varchar(max)))
from m,l
where mn = 1
and datalength(ms) < @limit
and ms not like '%[0-9]%')
select ms from m
where mn = 1 and ms not like '%[0-9]'
option (maxrecursion 0)

This will return all of the strings with length of @limit or below which pass ISNUMERIC() even though they don't contain any digits.
Post #993591
Posted Monday, September 27, 2010 6:49 AM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Thursday, July 24, 2014 8:41 AM
Points: 2,818, Visits: 2,553
Good discussion, good question.
Post #993610
Posted Monday, September 27, 2010 8:04 AM


Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Wednesday, May 28, 2014 1:04 PM
Points: 1,313, Visits: 1,055
Experimenting with the code in this question, I am getting different results from two SQL 2008 servers. One evaluates '\' as numeric. The other doesn't. They both have collation SQL_Latin1_General_CP1_CI_AS. Can anyone point me in the right direction on how to research what setting might be different between the two servers? Thanks.
Post #993658
Posted Monday, September 27, 2010 8:11 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 9:23 AM
Points: 5,925, Visits: 8,173
wware (9/27/2010)
Experimenting with the code in this question, I am getting different results from two SQL 2008 servers. One evaluates '\' as numeric. The other doesn't. They both have collation SQL_Latin1_General_CP1_CI_AS. Can anyone point me in the right direction on how to research what setting might be different between the two servers? Thanks.

The first things to look at would be the patch level (SELECT @@VERSION) and the compatibility level (SELECT name, compatibility_level FROM sys.database)



Hugo Kornelis, SQL Server MVP
Visit my SQL Server blog: http://sqlblog.com/blogs/hugo_kornelis
Post #993664
Posted Monday, September 27, 2010 8:31 AM


Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Wednesday, May 28, 2014 1:04 PM
Points: 1,313, Visits: 1,055
Thank you, Hugo. (The one that evaluates '\' as a number has compatability level 100. The other one has compatability level 80.)
Post #993681
« Prev Topic | Next Topic »

Add to briefcase «««12345»»»

Permissions Expand / Collapse