tempdb Database

 

Published: February 11, 2016

Updated: March 4, 2016

Applies To: SQL Server 2016

The tempdb system database is a global resource that is available to all users connected to the instance of SQL Server and is used to hold the following:

  • Temporary user objects that are explicitly created, such as: global or local temporary tables, temporary stored procedures, table variables, or cursors.

  • Internal objects that are created by the SQL Server Database Engine, for example, work tables to store intermediate results for spools or sorting.

  • Row versions that are generated by data modification transactions in a database that uses read-committed using row versioning isolation or snapshot isolation transactions.

  • Row versions that are generated by data modification transactions for features, such as: online index operations, Multiple Active Result Sets (MARS), and AFTER triggers.

Operations within tempdb are minimally logged. This enables transactions to be rolled back. tempdb is re-created every time SQL Server is started so that the system always starts with a clean copy of the database. Temporary tables and stored procedures are dropped automatically on disconnect, and no connections are active when the system is shut down. Therefore, there is never anything in tempdb to be saved from one session of SQL Server to another. Backup and restore operations are not allowed on tempdb.

The following table lists the initial configuration values of the tempdb data and log files. The sizes of these files may vary slightly for different editions of SQL Server.

FileLogical namePhysical nameInitial sizeFile growth
Primary datatempdevtempdb.mdf8 megabytesAutogrow by 64 MB until the disk is full
Secondary data files*temp#tempdb_mssql_#.ndf8 megabytesAutogrow by 64 MB until the disk is full
Logtemplogtemplog.ldf8 megabytesAutogrow by 64 megabytes to a maximum of 2 terabytes

* The number of files depends on the number of (logical) cores on the machine. The value will be the number of cores or 8, whichever is lower.
The default value for the number of data files is based on the general guidelines in KB 2154845.

In SQL Server, tempdb performance is improved in the following ways:

  • Temporary tables and table variables may be cached. Caching allows operations that drop and create the temporary objects to execute very quickly and reduces page allocation contention.

  • Allocation page latching protocol is improved. This reduces the number of UP (update) latches that are used.

  • Logging overhead for tempdb is reduced. This reduces disk I/O bandwidth consumption on the tempdb log file.

  • Setup adds multiple tempdb data files during a new instance installation. This task can be accomplished with the new UI input control on the Database Engine Configuration section and a command line parameter /SQLTEMPDBFILECOUNT. By default, setup will add as many tempdb files as the CPU count or 8, whichever is lower.

  • When there are multiple tempdb data files, all files will autogrow at same time and by the same amount depending on growth settings. Trace flag 1117 is no longer required.

  • All allocations in tempdb use uniform extents. Trace flag 1118 is no longer required.

  • For the primary filegroup, the AUTOGROW_ALL_FILES property is turned on and the property cannot be modified.

Moving the tempdb Data and Log Files

To move the tempdb data and log files, see Move System Databases.

Database Options

The following table lists the default value for each database option in the tempdb database and whether the option can be modified. To view the current settings for these options, use the sys.databases catalog view.

Database optionDefault valueCan be modified
ALLOW_SNAPSHOT_ISOLATIONOFFYes
ANSI_NULL_DEFAULTOFFYes
ANSI_NULLSOFFYes
ANSI_PADDINGOFFYes
ANSI_WARNINGSOFFYes
ARITHABORTOFFYes
AUTO_CLOSEOFFNo
AUTO_CREATE_STATISTICSONYes
AUTO_SHRINKOFFNo
AUTO_UPDATE_STATISTICSONYes
AUTO_UPDATE_STATISTICS_ASYNCOFFYes
CHANGE_TRACKINGOFFNo
CONCAT_NULL_YIELDS_NULLOFFYes
CURSOR_CLOSE_ON_COMMITOFFYes
CURSOR_DEFAULTGLOBALYes
Database Availability OptionsONLINE

MULTI_USER

READ_WRITE
No

No

No
DATE_CORRELATION_OPTIMIZATIONOFFYes
DB_CHAININGONNo
ENCRYPTIONOFFNo
MIXED_PAGE_ALLOCATIONOFFNo
NUMERIC_ROUNDABORTOFFYes
PAGE_VERIFYCHECKSUM for new installations of SQL Server.

NONE for upgrades of SQL Server.
Yes
PARAMETERIZATIONSIMPLEYes
QUOTED_IDENTIFIEROFFYes
READ_COMMITTED_SNAPSHOTOFFNo
RECOVERYSIMPLENo
RECURSIVE_TRIGGERSOFFYes
Service Broker OptionsENABLE_BROKERYes
TRUSTWORTHYOFFNo

For a description of these database options, see ALTER DATABASE SET Options (Transact-SQL).

The following operations cannot be performed on the tempdb database:

  • Adding filegroups.

  • Backing up or restoring the database.

  • Changing collation. The default collation is the server collation.

  • Changing the database owner. tempdb is owned by sa.

  • Creating a database snapshot.

  • Dropping the database.

  • Dropping the guest user from the database.

  • Enabling change data capture.

  • Participating in database mirroring.

  • Removing the primary filegroup, primary data file, or log file.

  • Renaming the database or primary filegroup.

  • Running DBCC CHECKALLOC.

  • Running DBCC CHECKCATALOG.

  • Setting the database to OFFLINE.

  • Setting the database or primary filegroup to READ_ONLY.

Any user can create temporary objects in tempdb. Users can only access their own objects, unless they receive additional permissions. It is possible to revoke the connect permission to tempdb to prevent a user from using tempdb, but this is not recommended as some routine operations require the use of tempdb.

SORT_IN_TEMPDB Option For Indexes

System Databases

sys.databases (Transact-SQL)

sys.master_files (Transact-SQL)

Move Database Files

Working with tempdb in SQL Server 2005

Community Additions

ADD
Show: