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

  • Cheers for that Mike.  I'm coming from an Oracle background and in older editions OUTER JOIN=Full Table Scan.

    I spent a bit more time looking into EXISTS after my post, and see what you mean.  When you code EXISTS rather than IN the first time it hits success it breaks the analysis loop.  This will be quicker if you are bringing back a huge number of rows from the subquery.

    HOWEVER, by the same rational NOT EXISTS should not be quicker than NOT IN AS it would have to scan the entire result set to ensure a single occurence isn't present.  Seems to follow...

  • No problem Dave.  There is a difference between NOT EXISTS and NOT IN in some cases.  Consider the following sample:

    CREATE TABLE #test (id INT PRIMARY KEY,

     val VARCHAR(20));

    INSERT INTO #test (id, val)

    SELECT 1, 'One'

    UNION SELECT 2, 'Two'

    UNION SELECT 3, 'Three'

    UNION SELECT 4, 'Four'

    UNION SELECT 5, 'Five';

    CREATE TABLE #odd (id INT);

    CREATE NONCLUSTERED INDEX ix1

    ON #odd(id);

    go

    WITH Num (n)

    AS

    (

     SELECT 1

     UNION ALL

     SELECT n + 1

     FROM Num

     WHERE n < 10000

    )

    INSERT INTO #odd (id)

    SELECT n

    FROM Num

    OPTION (MAXRECURSION 0)

    go

    SELECT *

    FROM #odd

    WHERE id NOT IN (

     SELECT id

     FROM #test

    );

    go

    SELECT *

    FROM #odd

    WHERE NOT EXISTS (

     SELECT id

     FROM #test

     WHERE #test.id = #odd.id

    );

    go

    drop table #test;

    drop table #odd;

    On my computer it generates two different query plans.  NOT EXISTS generates a query plan with a cost of 0.0614788.  NOT IN generates a query plan with substantially higher cost of 0.121561.  For small data sets in both tables the two queries generated the same query plan.

    EXISTS is not just about breaking the loop, the SELECT in EXISTS uses a correlated subquery and can potentially take advantage of indexes on the table.  In the best case this could result in efficient index seeks in the subquery, depending on which query plan SQL Server decides to go with.

  • Wow.  Tested it out and got the same results on mine.  Will definitely bear that one in mind.

    Thanks Mike!

  • By far the best solution as it relates most closely to the problem to be solved. I also prefer to use "EXISTS" rather than "IN" as you can't use "IN" efficiently if you have a composite key.

    Worth noting that you can use use " select * " rather than " select 1 " or " select 12345 " for that matter.

  • Worth noting that you can use use " select * " rather than " select 1 " or " select 12345 " for that matter.

    I have a sneaking suspicion that using select * or select column could result in a bookmark lookup (or RID lookup) if your query includes columns that are non-clustered index columns or non-indexed columns (particularly in the WHERE clause or in joins).  Select 1 or select 12345 shouldn't encounter that problem.

Viewing 5 posts - 31 through 34 (of 34 total)

You must be logged in to reply to this topic. Login to reply