Biggest difference between Temp tables and Table variables in Sql Server
We've all heard about differences between temporary tables and table variables in SQL Server.
They include performance, storage in memory or disk, tempdb use, etc.
But the biggest and mostly overlooked difference is:
Table variables are Transaction neutral. They are variables and thus aren't bound to a transaction.
Temp tables behave same as normal tables and are bound by transactions.
A simple example shows this difference quite nicely:
BEGIN TRAN declare @var table (id int, data varchar(20) ) create table #temp (id int, data varchar(20) )insert into @var select 1, 'data 1' union all select 2, 'data 2' union all select 3, 'data 3'
insert into #temp select 1, 'data 1' union all select 2, 'data 2' union all select 3, 'data 3'
select * from #temp select * from @var
ROLLBACK
select * from @var if object_id('tempdb..#temp') is null select '#temp does not exist outside the transaction'
We see that the table variable still exists and has all it's data unlike the temporary table that doesn't exists when the transaction rollbacked.
This little known fact can be very handy in a bunch of different scenarions.
I showed one with auditing here.
|
Legacy Comments
Sanjiv
2007-12-30 |
re: Biggest difference between Temp tables and Table variables in Sql Server good one |
mouli
2008-07-18 |
re: Biggest difference between Temp tables and Table variables in Sql Server Superb Explanation... |
Thanigainathan S
2008-10-13 |
re: Biggest difference between Temp tables and Table variables in Sql Server very good explanation |
Sivakumar
2008-12-17 |
re: Biggest difference between Temp tables and Table variables in Sql Server Nice Example |
Raghu
2009-03-05 |
re: Biggest difference between Temp tables and Table variables in Sql Server Really a good and helpful explanation. Keep going. |
Barnana
2009-04-10 |
re: Biggest difference between Temp tables and Table variables in Sql Server Very well explained |
KK
2009-04-25 |
re: Biggest difference between Temp tables and Table variables in Sql Server Ultimate example..... |
Munish
2009-08-23 |
re: Biggest difference between Temp tables and Table variables in Sql Server Amazing one |
Kalyan
2009-10-03 |
re: Biggest difference between Temp tables and Table variables in Sql Server Excellent One... 100% working ... Such a gr8 article |
Mukesh
2009-11-23 |
re: Biggest difference between Temp tables and Table variables in Sql Server Good diff. |
Kiruthika
2009-11-29 |
re: Biggest difference between Temp tables and Table variables in Sql Server I like the way of explanation. Very good one. Need to bookmark..... |
prasad
2009-12-17 |
re: Biggest difference between Temp tables and Table variables in Sql Server Good one....i liked the way of explanation.... |
Surojit
2010-03-07 |
re: Biggest difference between Temp tables and Table variables in Sql Server A nice example to show an important distinction. |
Raj Thakur
2010-03-12 |
re: Biggest difference between Temp tables and Table variables in Sql Server Nice explanation....... Keep it up |
Pravin S. Ahire
2010-03-29 |
re: Biggest difference between Temp tables and Table variables in Sql Server 1) Transaction logs are not recorded for the table variables, hence they are out of scope of the transaction mechanism. While Transaction logs are recorded for the temporary table. 2) Any procedure with a temporary table cannot be pre-compiled, while an execution plan of procedures with table variables can be statically compiled in advance. |
mohideen
2010-04-01 |
re: Biggest difference between Temp tables and Table variables in Sql Server good point. |
Santosh Kumar
2010-04-05 |
re: Biggest difference between Temp tables and Table variables in Sql Server Good Explanation. Really It clarified me. |
Pawan Kumar
2010-05-27 |
re: Biggest difference between Temp tables and Table variables in Sql Server very good and simple example... Table variables don't participate in transactions, logging or locking. This means they're faster. Temporary Tables are real tables so you can do things like CREATE INDEXes, etc. If you have large amounts of data for which accessing by index will be faster then temporary tables are a good option You can create a temp table using SELECT INTO, which can be quicker to write and may allow you to deal with changing datatypes over time, since you don't need to define your temp table structure upfront. Both table variables and temp tables are stored in tempdb. This means you should be aware of issues such as COLLATION problems if your database collation is different to your server collation; temp tables and table variables will by default inherit the collation of the server, causing problems if you want to compare data in them with data in your database. |
siva
2010-06-21 |
re: Biggest difference between Temp tables and Table variables in Sql Server very good |
Pushkar Gupta
2010-07-09 |
re: Biggest difference between Temp tables and Table variables in Sql Server Excellent Example |
suba
2010-09-21 |
What is the service level difference between sql server 2000 and 2005 What is the service level difference between sql server 2000 and 2005 |
Suresh Kala
2010-10-01 |
re: Biggest difference between Temp tables and Table variables in Sql Server Excellent Explanation. It is very helpful. |
Badri
2010-10-04 |
re: Biggest difference between Temp tables and Table variables in Sql Server Amazing..... |