RSS

Table spools operator used in SQL server query plans

25 Apr

Table spools in SQL server are temporary result sets used by SQL server query optimizer. You might see this operator in SQL server query execution plans. Let’s see this with an example. We can create a simple test table with following script.

IF (OBJECT_ID('test') IS NOT NULL)
BEGIN
DROP TABLE test
END
GO

--Create test table 
CREATE TABLE test    
( Id INT IDENTITY(1, 1) , 
[Name] CHAR(1000) DEFAULT 'test value')          
GO   
-- insert 1000 test records 

INSERT INTO dbo.test 
DEFAULT VALUES  
GO 100

CREATE CLUSTERED INDEX IX_test_Name ON dbo.test(Name ASC)
GO

If we do an update to the test table by including actual execution plan (graphical in this case) using following query we will get following sort of graphical execution plan

-- run the update query with include actual execution plan
UPDATE dbo.test set [Name] = NEWID()

table_spool
We can see that there is a table spool in the middle of the table update. Why SQL server creates table spool here is noteworthy to understand since it has 39% cost which seems like unnecessary additional cost but actually it is a sort of protection mechanism pushed by SQL server for common problem known as “Halloween Protection”. When an update query is being executed it has two operations. One is done by read cursor which does the reading of rows to be updated and the other half is write cursor which actually does the row changes. Let’s understand this with above example, since my test table has clustered index on “Name” column and clustered index enforces physical order of the table updating the clustered index column with new values might change physical order of the table so if the read cursor and write cursor in SQL server went simultaneously write cursor might do the update more than once while traversing the physical structure of the clustered index. So to prevent that SQL server creates a temporary result set in tempdb know as table spool with the result set of the read cursor(which is eager Spool since it will block parent operation until all rows are being read) . That result set will be updated so this is the “Halloween Protection” enforced by SQL server. This issue is identified by IBM researchers more than 30 years ago.
If you drop the clustered index and run the update query again you will NOT see the table spool since you are not updating physically ordered clustered index hence no threat of “Halloween Issue”. We can confirm this with Query plan as following.

--drop the clustered index
DROP INDEX IX_test_Name ON dbo.test
GO
-- run the update query again and see execution plan
UPDATE dbo.test set [Name] = NEWID()

with no clustered index no table spool

Advertisements
 
Leave a comment

Posted by on April 25, 2013 in MS SQL Server, SQL, TSQL

 

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s

 
%d bloggers like this: