SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


The Pitfall of "Not Equal To" Operator in Queries!


The Pitfall of "Not Equal To" Operator in Queries!

Author
Message
Dennis D. Allen
Dennis D. Allen
SSC Veteran
SSC Veteran (289 reputation)SSC Veteran (289 reputation)SSC Veteran (289 reputation)SSC Veteran (289 reputation)SSC Veteran (289 reputation)SSC Veteran (289 reputation)SSC Veteran (289 reputation)SSC Veteran (289 reputation)

Group: General Forum Members
Points: 289 Visits: 163
The question is one of membership, and the IN clause seems to be a very clear way to pose that question. After proper indexing, it yields the same query plan as the methods proposed, but in a more understandable query.

/* Students that have taken the SQL Server test */
SELECT s.*
FROM dbo.Students AS s
WHERE s.StID IN (SELECT StID FROM dbo.StudentExam WHERE ExamName = 'SQL Server')

/* Students that have not taken the SQL Server test */
SELECT s.*
FROM dbo.Students AS s
WHERE s.StID NOT IN (SELECT StID FROM dbo.StudentExam WHERE ExamName = 'SQL Server')
YSLGuru
YSLGuru
SSCertifiable
SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)

Group: General Forum Members
Points: 7478 Visits: 1668

Regardless of the material, a thanks to Amin Sobati for writing it. I often wonder why any of these contributing authors would take the time to produce material when too often that maetrial recieves not just constructive criticism but out right crude & rude behaivor. Is it necessary to sue workds like 'stupid' in a constructive criticism?



Kindest Regards,

Just say No to Facebook!
Scalability Doug
Scalability Doug
SSCrazy
SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)

Group: General Forum Members
Points: 2413 Visits: 6111

This is a classic example of an exclusion list and point sout the limitiations of the inequality operator. What is presented in this example is that members in one are are to be excluded from from others. (Note that the example is students who have not taken the SQL Server exam. Bob gets omitted. Does he get omitted because he has not taken an exam?). And as the author points out, "you can simply use a subquery to build the list of students who have taken SQL Server exam" and then build your exclusion using the NOT EXISTS clause:

SELECT s.*
FROM Students s
where
not exists ( select stid from studentExam se where s.StID = stid and examname = 'SQL Server' )


Mike C
Mike C
SSCrazy Eights
SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)

Group: General Forum Members
Points: 9685 Visits: 1172

"ANY COMPARISON OF A NON-NULL TO A NULL IS NULL"

Actually comparisons of a NULL (or a non-NULL value) to a NULL results in UNKNOWN. Your point is taken though: The WHERE clause only returns results for rows comparisons that evaluate to TRUE. Comparisons that evaluate to FALSE or UNKNOWN are dropped from the results.


Tim Chapman-218780
Tim Chapman-218780
Mr or Mrs. 500
Mr or Mrs. 500 (509 reputation)Mr or Mrs. 500 (509 reputation)Mr or Mrs. 500 (509 reputation)Mr or Mrs. 500 (509 reputation)Mr or Mrs. 500 (509 reputation)Mr or Mrs. 500 (509 reputation)Mr or Mrs. 500 (509 reputation)Mr or Mrs. 500 (509 reputation)

Group: General Forum Members
Points: 509 Visits: 115

I 100% agree with the comment made by Duray AKAR. The query listed will never retrieve the results "the students that has not taken the "SQL Server" exam...will only return those results for students that have taken an exam that is not SQL Server. Very good point Duray AKAR.

Tim


Antares686
Antares686
SSC-Forever
SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)

Group: Moderators
Points: 40856 Visits: 803

The issue isn't the use of <> or != (which I prefer the later). The pitfall is in presumption of the data and our understanding of the question.

The question being asked that fits your final solution is

"Which students haven't taken the %s exam?"

In your first solution the question is more to the effect

"List the students who have taken exams each time but do not show the times the %s exam was taken."

If you had used left join

"List the students who have taken exams each time but do not show the times the %s exam was taken and make sure to show those who haven't taken an exam at all at least once."

The biggest issue with generating data for reports is always making sure you understand the intended result fully and structure the query correctly. Some syntax is more prone than others to creating the structure that represents the question you want to pose. As always thou there can be dozens of ways to ask the same question and get the correct answer, then it is a matter of most effective way.





Antares686
Antares686
SSC-Forever
SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)

Group: Moderators
Points: 40856 Visits: 803
Sorry, still a good contribution thou.



Ken Shapley
Ken Shapley
SSC-Enthusiastic
SSC-Enthusiastic (170 reputation)SSC-Enthusiastic (170 reputation)SSC-Enthusiastic (170 reputation)SSC-Enthusiastic (170 reputation)SSC-Enthusiastic (170 reputation)SSC-Enthusiastic (170 reputation)SSC-Enthusiastic (170 reputation)SSC-Enthusiastic (170 reputation)

Group: General Forum Members
Points: 170 Visits: 173

y <> x and x <> z then y could possibly = z

This is not a pitfall, but merely an oversight sometimes.


Andy DBA
Andy DBA
Say Hey Kid
Say Hey Kid (664 reputation)Say Hey Kid (664 reputation)Say Hey Kid (664 reputation)Say Hey Kid (664 reputation)Say Hey Kid (664 reputation)Say Hey Kid (664 reputation)Say Hey Kid (664 reputation)Say Hey Kid (664 reputation)

Group: General Forum Members
Points: 664 Visits: 775

"Actually comparisons of a NULL (or a non-NULL value) to a NULL results in UNKNOWN. Your point is taken though: The WHERE clause only returns results for rows comparisons that evaluate to TRUE. Comparisons that evaluate to FALSE or UNKNOWN are dropped from the results."

Well now we're splitting hairs! But, Mike is absolutely right. BOL defines the result for those comparisons to be "UNKNOWN". I've always considered NULL and UNKNOWN to mean the same thing and, interestingly enough, when you look up "unknown data" in BOL you get the "Null Values" overview page! There must be some subtle distinction though, otherwise the authors would have used NULL instead of UNKNOWN.


Sorry to take this thread so far off topic, but here's an interesting puzzler (while we're splitting hairs). I apologize if this topic has already been covered elsewhere.


I refrained from bringing up the ANSI_NULLS setting before, but it adds an interesting twist. According to 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.

and

When ANSI_NULLS is OFF, comparisons such as ColumnA = NULL return TRUE when ColumnA contains a null value and FALSE when ColumnA contains some value besides NULL. Also, a comparison of two expressions that have both evaluated to null values yields TRUE.

To confirm this, let's try some simple TSQL. Running the following produces what you'd expect (after reading BOL).

set ANSI_NULLS OFF
declare @string varchar(25)
set @string = 'TEST'
if @string <> NULL --compare a variable to explicit NULL
print 'true'
else
print 'not true'

set @string = NULL
if @string <> 'TEST' --compare a NULL variable to an explicit value
print 'true'
else
print 'not true'

SELECT 'true' where @string <> 'TEST' --try a comparison in a select.


Results
----
true
true

true

(1 row(s) affected)

set ANSI_NULLS ON and you get
Results
----
not true
not true


(0 row(s) affected)


So far so good. It looks like all we have to do to retrieve Bob in Ehsan's example is set ANSI_NULLS OFF, right?

set ANSI_NULLS OFF
SELECT * FROM Students s left outer join StudentExam se ON s.StID = se.StID WHERE se.ExamName<>'SQL Server'

Results
----
StID StName StID ExamName
2 Anna 2 VB.NET
2 Anna 2 C#.NET
1 Jack 1 XML

(3 row(s) affected)

Huh? Where is Bob? Hmmm. Let's continue to use ANSI_NULLS OFF and look for ExamName = NULL

set ANSI_NULLS OFF
SELECT * FROM Students s left outer join StudentExam se ON s.StID = se.StID WHERE se.ExamName=NULL

Results
----
StID StName StID ExamName
3 Bob

(1 row(s) affected)

There's Bob!

WHAT'S GOING ON HERE? How come se.ExamName=NULL evaluates to TRUE but se.ExamName<>'SQL Server' doesn't (with ANSI_NULLS OFF).

Is it because the NULL is "virtual" in the left join. Let's try one more experiment:

Insert Students VALUES (4,NULL)

set ANSI_NULLS OFF
SELECT * FROM STUDENTS WHERE StName = NULL

Results
----
StID StName
4

(1 row(s) affected)

So far so good. Let's try the dratted "not equals to" operator that started this whole mess:

set ANSI_NULLS OFF
SELECT * FROM STUDENTS WHERE StName <> 'Nobody'

Results
----
StID StName
1 Jack
2 Anna
3 Bob

(3 row(s) affected)

WHAT? Where's the new row we just inserted? Must be that pesky "not equals to" operator. Double negative anyone?

set ANSI_NULLS OFF
SELECT * FROM STUDENTS WHERE not StName <> NULL

Results
----
StID StName
4

(1 row(s) affected)

Sure, there it is. So it must not be the "not equals to" operator?


My advice to anyone still reading: BE VERY CAREFUL WITH "SET ANSI_NULLS OFF" AND ANY COMPARISONS WITH NULLS AND BE ESPECIALLY CAREFUL WITH THE <> OPERATOR AND NULLS.





herb walles
herb walles
SSC Veteran
SSC Veteran (240 reputation)SSC Veteran (240 reputation)SSC Veteran (240 reputation)SSC Veteran (240 reputation)SSC Veteran (240 reputation)SSC Veteran (240 reputation)SSC Veteran (240 reputation)SSC Veteran (240 reputation)

Group: General Forum Members
Points: 240 Visits: 1

The best way to think about it as "NOT EXISTS". This is the most logical human approach. You can always convert "not exists" into "left join"

select s.* from #students s
where not exists
(
select 1 from #StudentExam where stid=s.stid and Examname='SQL Server'
)


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