October 27, 2010 at 10:20 pm
Comments posted to this topic are about the item Output of Query
October 27, 2010 at 11:12 pm
thanks for the Nice Question 🙂
To get the records with NULL value the WHERE condition needs to rewrite as WHERE NullableColumn <> '1' OR NullableColumn IS NULL.
For the above you can write like this also
SET ANSI_NULLS OFF
GO
SELECT NullableColumn FROM NullOperation WHERE NullableColumn IN('1' ,NULL)
GO
it will depends on SET OPTION
Reference http://msdn.microsoft.com/en-us/library/ms188048(SQL.90).aspx"> http://msdn.microsoft.com/en-us/library/ms188048(SQL.90).aspx
October 28, 2010 at 1:05 am
Good question, but a small (yet significan) mistake in the explanation.
NULL does not represent the value 'UNKNOWN'. NULL is a marker for a missing value, without any indication as to why the value is missing - the value being unknown is one of the possible reasons, but far from the only one; not applicable being the second-most common reason, and a whole bunch of less common reasons to follow.
Since a comparison with a missing value can never result in either of the truth values True of False, such comparisons will result in the third truth value, Unknown. So while NULL is not the same as Unknown, it does have the effect to make 1 <> NULL result in Unknown.
I have explained this in far more detail in a four-part series on my blog:
* NULL - The database's black hole
* The logic of three-valued logic
* Dr. Unknown, or how I learned to stop worrying and love the NULL
* What if null if null is null null null is null?
I must say that I am also very surprised (and disappointed) by the amount of incorrect answers. Almost 25% of respondents expect NULL to be returned as well - much more that I expected, because this is far from the first time that the effects of NULL in comparisons have been tested in the QotD.
October 28, 2010 at 1:14 am
deepak.a (10/27/2010)
To get the records with NULL value the WHERE condition needs to rewrite as WHERE NullableColumn <> '1' OR NullableColumn IS NULL.For the above you can write like this also
SET ANSI_NULLS OFF
GO
SELECT NullableColumn FROM NullOperation WHERE NullableColumn IN('1' ,NULL)
GO
it will depends on SET OPTION
Reference http://msdn.microsoft.com/en-us/library/ms188048(SQL.90).aspx"> http://msdn.microsoft.com/en-us/library/ms188048(SQL.90).aspx
This is not equivalent; the original query excludes the value '1', whereas the IN clause includes '1' and NULL and excludes all others.
If you use SET ANSI_NULLS OFF, there is no need to rewrite anyway. The ANSI_NULLS affects all comparisons with NULL, not only those in a [NOT] IN expression.
And beware that the ANSI_NULLS OFF option is deprecated since SQL Server 2008. This option will be removed in a future version; don't build any new code that relies on this setting. (Though you should never have in the first placve, given how extremely non-standard this option is).
October 28, 2010 at 1:28 am
Hugo Kornelis (10/28/2010)
deepak.a (10/27/2010)
To get the records with NULL value the WHERE condition needs to rewrite as WHERE NullableColumn <> '1' OR NullableColumn IS NULL.For the above you can write like this also
SET ANSI_NULLS OFF
GO
SELECT NullableColumn FROM NullOperation WHERE NullableColumn IN('1' ,NULL)
GO
it will depends on SET OPTION
Reference http://msdn.microsoft.com/en-us/library/ms188048(SQL.90).aspx"> http://msdn.microsoft.com/en-us/library/ms188048(SQL.90).aspx
This is not equivalent; the original query excludes the value '1', whereas the IN clause includes '1' and NULL and excludes all others.
If you use SET ANSI_NULLS OFF, there is no need to rewrite anyway. The ANSI_NULLS affects all comparisons with NULL, not only those in a [NOT] IN expression.
And beware that the ANSI_NULLS OFF option is deprecated since SQL Server 2008. This option will be removed in a future version; don't build any new code that relies on this setting. (Though you should never have in the first placve, given how extremely non-standard this option is).
Sorry i made a mistake and thanks hugo for your explanantion
October 28, 2010 at 1:36 am
-- non standard ansi
SELECT NullableColumn FROM NullOperation WHERE ISNULL(NullableColumn,'') <> '1'
OR
-- standard ansi
SELECT NullableColumn FROM NullOperation WHERE COALESCE(NullableColumn,'') <> '1'
October 28, 2010 at 2:29 am
simple Question,
but the article that hugo has written are truly informative.
October 28, 2010 at 2:58 am
Hugo Kornelis (10/28/2010)
If you use SET ANSI_NULLS OFF, there is no need to rewrite anyway. The ANSI_NULLS affects all comparisons with NULL, not only those in a [NOT] IN expression.
Setting this option wouldn't be enough, because it doesn't affect the comparison of a nullable column with a not-null value.
SET ANSI_NULLS OFF;
GO
SELECT NullableColumn FROM NullOperation WHERE NullableColumn <> '1';
GO
NullableColumn
--------------
0
(1 row(s) affected)
But the comparison of a column with NULL is affected:
SET ANSI_NULLS ON;
GO
SELECT NullableColumn FROM NullOperation WHERE NullableColumn <> NULL;
GO
NullableColumn
--------------
(0 row(s) affected)
SET ANSI_NULLS OFF;
GO
SELECT NullableColumn FROM NullOperation WHERE NullableColumn <> NULL;
GO
NullableColumn
--------------
0
1
(2 row(s) affected)
October 28, 2010 at 3:09 am
Hugo Kornelis (10/28/2010)
I must say that I am also very surprised (and disappointed) by the amount of incorrect answers. Almost 25% of respondents expect NULL to be returned as well - much more that I expected, because this is far from the first time that the effects of NULL in comparisons have been tested in the QotD.
Looking on the bright side it means that 25% of responders will have learnt something today. That's what this site is about as well. I suppose I get about half of the questions wrong, mainly on topics that I have never had to deal with as part of my work.
October 28, 2010 at 3:14 am
vk-kirov (10/28/2010)
Hugo Kornelis (10/28/2010)
If you use SET ANSI_NULLS OFF, there is no need to rewrite anyway. The ANSI_NULLS affects all comparisons with NULL, not only those in a [NOT] IN expression.Setting this option wouldn't be enough, because it doesn't affect the comparison of a nullable column with a not-null value.
Woah! You are so right - thanks for correcting me. That'll teach e to comment on features I avoid like the plague :w00t:
And I also caught another error in my previous post. SET ANSI_NULLS is not deprecated since SQL Server 2008, but since SQL Server 2005. That means even less time to revisit old code that uses this feature (phew, am I glad I don't have any :-D)
(PS: Thank you for the kind words, sharath.chalamgari - I am glad you found the information useful)
October 28, 2010 at 6:47 am
Regular reiteration of how nulls behave is very useful in QoTD. Thanks.
October 28, 2010 at 9:48 am
Thanks for the question!
October 28, 2010 at 12:58 pm
Hugo Kornelis (10/28/2010)
Good question, but a small (yet significan) mistake in the explanation.NULL does not represent the value 'UNKNOWN'.
Hugo, perhaps you could ask M$ to update the books online to match your opinion?
<Quote from BOL>
When SET ANSI_NULLS is ON, a comparison in which one or more of the expressions is NULL does not yield either TRUE or FALSE; it yields UNKNOWN. This is because a value that is unknown cannot be compared logically against any other value. This occurs if either an expression is compared to the literal NULL, or if two expressions are compared and one of them evaluates to NULL. For example, the following comparison always yields UNKNOWN when ANSI_NULLS is ON:
Copyytd_sales > NULL
The following comparison also yields UNKNOWN any time the variable contains the value NULL:
ytd_sales > @MyVariable
<Quote from BOL>
Youre comment is correct with one small but significant correction.
When ANSI_NULLS is OFF NULL is not value UNKNOWN.
October 28, 2010 at 1:04 pm
Great question Sunil.
Good example of how NULLS are counted in a column of data.
I also give this question 5 stars for having no typos or confusion in the code, question, or answers!
😎
October 28, 2010 at 3:05 pm
SanDroid (10/28/2010)
Hugo Kornelis (10/28/2010)
Good question, but a small (yet significan) mistake in the explanation.NULL does not represent the value 'UNKNOWN'.
Hugo, perhaps you could ask M$ to update the books online to match your opinion?
<Quote from BOL>
When SET ANSI_NULLS is ON, a comparison in which one or more of the expressions is NULL does not yield either TRUE or FALSE; it yields UNKNOWN. This is because a value that is unknown cannot be compared logically against any other value. This occurs if either an expression is compared to the literal NULL, or if two expressions are compared and one of them evaluates to NULL. For example, the following comparison always yields UNKNOWN when ANSI_NULLS is ON:
Copyytd_sales > NULL
The following comparison also yields UNKNOWN any time the variable contains the value NULL:
ytd_sales > @MyVariable
<Quote from BOL>
I wrote that NULL does not represent unknown. I also wrote that a comparison to NULL does result in the truth value Unknown.
You quote an excerpt from BOL that states that comparisons in which one or more of the operands are NULL yield Unknown. I fail to see the mismatch between the BOL quote and my post.
That being said, BOL does contain lots of errors - it is an excellent reference for the product SQL Server, but it is far from perfect when it comes to relational theory.
Youre comment is correct with one small but significant correction.
When ANSI_NULLS is OFF NULL is not value UNKNOWN.
I already admitted in a previous post that I never use ANSI_NULLS off. (And that no one should, really)
Viewing 15 posts - 1 through 15 (of 20 total)
You must be logged in to reply to this topic. Login to reply