Overview
Were you aware that the act of populating a temporary table can cause
system-wide bottlenecks on your server? Problems can occur both with SQL
Server 6.5 and 7 in different ways, and in this article I will discuss how best
to avoid them.
Bottlenecks in version 6.5
Many people use a select...into query to create a temporary table,
something like this:
select *
into #tempTable
from source
While this works, it creates locks against the temporary database for the
duration of the select statement (quite a while if you are trawling through a
lot of data in the source table, and longer still if the select...into is at the start of a
longer-running explicit transaction) While this lock is in place, no other user
can create temporary tables. The actual location of the bottleneck is a lock on
tempdb system tables. In later versions of SQL Server the locking model has
changed and the problem is avoided.
If a number of concurrent processes are trying to load temporary tables in
this way, particularly if large amounts of data are involved, then a bottleneck
is inevitable.
The trick to freeing up tempdb is to ensure that the "create temporary
table" part of the operation is committed as quickly as possible. To do
this, recode the above statement it the following format:
create table #temp(
........
)
insert #temp
select *
from sourceTable
In this manner we create our temporary table and free the sysobjects or
schema lock as quickly as possible.
Short cut to a solution
If you want to avoid coding the insert...into statement, or if you are writing a generic piece of
code and will not know the exact table definition until run-time, you can revert
to this trick:
select *
into #temp
from sourceTable
where 1 = 0
insert #temp
select *
from sourceTable
Obviously where 1 = 0 is never true. No matter how much data is in sourceTable
SQL Server's optimiser is usually smart enough to realise that because one is
never equal to zero, it's not worth trawling through the source table. (If I can
I always
check the query execution plan just to make sure, but I have never caught it out yet)
Even though SQL Server will not trawl through the source table,
the #temp table will still be defined, based on the format of the
data in the select statement, but it will
contain no rows. You can then run the insert...select statement secure in
the knowledge that you are not blocking other processes access to the tempdb.
Bottlenecks in version 6.5 and 7
For the most part, the problem described above does not apply to version 7,
but there is is one instance where you can still unintentionally create these
bottlenecks under either version.
The problem arises when you use the INSERT...EXEC statement to load a temporary
table, and the stored procedure itself creates temporary tables, you end up with
blocking locks in tempdb similar to those described above. The prescribed
workarounds are either "don't do it in the first place", which is
inconvenient if you do not want to mess with legacy code or code you do not
control, or otherwise to execute the stored procedure as a remote stored
procedure, (i.e. "INSERT #temp EXEC server.database.owner.proc") which
again is not ideal in all circumstances.
Further reading
Check out this Technet
article for more information on tempdb locking problems in SQL 6.5, and see this
article for both versions 6.5 and 7
About the author
Neil Boyle is an independent SQL Server consultant working out of London,
England. Neil's free SQL Server guide is available on-line at http://www.impetus-sql.co.uk