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 12»»

any way this can avoid of index scan? Expand / Collapse
Author
Message
Posted Wednesday, July 17, 2013 4:04 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Sunday, July 20, 2014 9:50 PM
Points: 32, Visits: 300
Hi, it looks impossible to me, but, is anyone know could this kind of query avoid of index scan?

select * from A where col1 not in (select col1 from B)

thank you all!
Post #1474477
Posted Wednesday, July 17, 2013 4:28 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Yesterday @ 2:44 PM
Points: 42,443, Visits: 35,498
No, that will require a scan of both tables.


Gail Shaw
Microsoft Certified Master: SQL Server 2008, MVP
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass

Post #1474484
Posted Wednesday, July 17, 2013 4:42 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 9:56 AM
Points: 7,120, Visits: 13,491
sqlnes (7/17/2013)
Hi, it looks impossible to me, but, is anyone know could this kind of query avoid of index scan?

select * from A where col1 not in (select col1 from B)

thank you all!


As Gail said, no, but there are scans and there are scans. Play with the following code and examine the execution plans of the two statements. Note also the NULL handling behaviour of NOT IN - is it what you were expecting?

DROP TABLE #A
SELECT TOP 10000 col1 = ROW_NUMBER() OVER (ORDER BY (SELECT NULL))
INTO #A
FROM syscolumns a, syscolumns b

CREATE UNIQUE CLUSTERED INDEX ucx_col1 ON #A (col1)


DROP TABLE #B
SELECT TOP 3 col1 = CAST(col1 AS INT)
INTO #B
FROM #A

INSERT INTO #B (col1) SELECT NULL

INSERT INTO #B (col1) SELECT TOP 10000 col1 = 10000+ROW_NUMBER() OVER(ORDER BY (SELECT NULL))

CREATE UNIQUE CLUSTERED INDEX ucx_col1 ON #B (col1)


-- full scan
SELECT a.col1
FROM #A a
WHERE a.col1 NOT IN (SELECT b.col1 FROM #B b)

-- range scan
SELECT a.col1
FROM #A a
WHERE NOT EXISTS (SELECT 1 FROM #B b WHERE b.col1 = a.col1)






“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Post #1474486
Posted Wednesday, July 17, 2013 6:25 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Sunday, July 20, 2014 9:50 PM
Points: 32, Visits: 300
Thank you Gail & Chris for explain.
Just checked my tables and the "col1" on both table are non null. So it seems it's unavoidable.
Post #1474541
Posted Wednesday, July 17, 2013 6:31 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 9:56 AM
Points: 7,120, Visits: 13,491
sqlnes (7/17/2013)
Thank you Gail & Chris for explain.
Just checked my tables and the "col1" on both table are non null. So it seems it's unavoidable.


What's unavoidable? (Apart from D & T of course)


“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Post #1474549
Posted Wednesday, July 17, 2013 7:06 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Sunday, July 20, 2014 9:50 PM
Points: 32, Visits: 300
2 index scans are unavoidable?
Post #1474587
Posted Wednesday, July 17, 2013 7:18 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 9:56 AM
Points: 7,120, Visits: 13,491
sqlnes (7/17/2013)
2 index scans are unavoidable?


That's correct. You can have an index scan too if you want - just up the ratio of looked-up rows to parent rows, but you're stuck with the scans. Like I said earlier, check the actual execution plans of the two alternative ways of writing the query. Run them together (run the prep part as a batch, then the two queries as a separate batch) to compare the plans one above the other. If you are unsure of what I mean by "not all scans are equal", look at the scan operators for the lookup tables in each plan.


“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Post #1474595
Posted Wednesday, July 17, 2013 7:31 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Sunday, July 20, 2014 9:50 PM
Points: 32, Visits: 300
Thanks Chris. And sorry I forgot to mention that I've followed your first reply and compared the explains and they are identical. Then I checked the column on my 2 tables and both are not null...
I guess may be I could ask the developer to add some more criterion on the first table would reduce the cost?
Post #1474607
Posted Wednesday, July 17, 2013 7:48 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 9:56 AM
Points: 7,120, Visits: 13,491
sqlnes (7/17/2013)
Thanks Chris. And sorry I forgot to mention that I've followed your first reply and compared the explains and they are identical. Then I checked the column on my 2 tables and both are not null...
I guess may be I could ask the developer to add some more criterion on the first table would reduce the cost?


Really? What type of join is shown for Query 1 and Query 2?
Query 2 is about 20x faster than Query 1 on this pc, with or without nullable columns.
I'm using 2K8, I wouldn't expect 2K5 to be much different.


“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Post #1474622
Posted Wednesday, July 17, 2013 7:51 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Yesterday @ 2:44 PM
Points: 42,443, Visits: 35,498
ChrisM@Work (7/17/2013)
Really? What type of join is shown for Query 1 and Query 2?


NOT IN and NOT EXISTS do perform identically with identical execution plans if the columns are defined as NOT NULL.
http://sqlinthewild.co.za/index.php/2010/02/18/not-exists-vs-not-in/



Gail Shaw
Microsoft Certified Master: SQL Server 2008, MVP
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass

Post #1474627
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse