We're in the weeds now.
Implicit data type conversions can cause weird, previously unknown problems to surface. Based on my previous post, it should be clear that when an implicit conversion exists between string (varchar et al) and number, sql server prefers to convert to number. This is a shame because all numbers can be converted to a string, but not all strings can be converted to numbers.
Code:
Declare @Temp Table(value varchar(10))
Insert into @temp Values(1)
Insert into @temp Values(2)
Insert into @temp Values(3)
Insert into @temp Values(4)
Insert into @temp Values(5)
Insert into @temp Values(11)
Select * From @Temp Where Value > 2
--
-- Value
-- 3
-- 4
-- 5
-- 11
Select * From @Temp Where Value > [!]'[/!]2[!]'[/!]
--
-- Value
-- 3
-- 4
-- 5
It's clear that the value column is a varchar(10). It should also be clear that we are inserting integers into that column. Looking at the last line, you might think the query would fail, but if you run this, you will see that it actually does exactly what you think it would.
The first select query (the one without the single quotes around the 2) returns exactly the same results that would be returned if the column was an integer, instead of a varchar. It does this because the where clause is treating the value column like an integer. Specifically, since you are comparing a varchar and an int, the implicit conversion will actually convert the string (in the table) to an int for the purposes of the comparison.
The second query is comparing a string with a string which is why '11' is less than '2'.
More fun? sure. Using the code above, add these 2 lines to the bottom and run it.
Code:
Insert Into @temp Values('six')
Select * From @Temp Where Value > 2
The insert works just fine because the column data type is a varchar, and we're inserting a varchar. However, notice that we are running the exact same query that we previously ran. Now you'll get an error.
Code:
[!]
Msg 245, Level 16, State 1, Line 15
Conversion failed when converting the varchar value 'six' to data type int.[/!]
The error message makes it obvious that every value in the table is getting converted to an integer for the purposes of the where clause. Not only can this lead to weird errors all of a sudden, but it can also cause performance problems with very large tables.
Bottom line, developers should always be careful with data types. It's easy to overlook them, so it can be difficult to do them consistently correct across all the queries in your database.
-George
Microsoft SQL Server MVP
My Blogs
SQLCop
twitter
"The great things about standards is that there are so many to choose from." - Fortune Cookie Wisdom