You can create tables in TempDb like you do in other databases and it does perform faster in TempDb because most of the internal operation doesn't generate log in TempDb as rollback is not required. The real issue with TempDb is missing "D" from ACID property which indicates
" That the database won't be able to keep track of pending changes by which server can recover from an abnormal termination "
So, even if you use TRANSACTION and server restarts you won't be able to recover it.
TempDb is an important part of SQL Server database as it manages a temporary object which includes:
Objects created internally by SQL Server to process SQL queries.
Created by users explicitly
A version store is a collection of data pages that hold the data row that are required to support features that uses row versioning.
Database which is using read-committed isolation
Note : Above specified list is a broad way specification of objects used by or in TempDb.
There are misconception about TempDb working and configuration, so below are few important point which shows the fact about TempDb
You can check properties of database by using sys.databases catalog view; sys.databases contains one row for each database and database_id ideally represents TempDb
USE [MASTER]
SELECT
*
FROM
sys.databases
WHERE
database_id = 2
Similarly, you can use sys.master_files catalog view to get the files related to TempDb database
sys.master_files
With the help of below DMV, you can check how much TempDb space does your session is using. This query is quite helpful while debugging TempDb issues
sys.dm_db_session_space_usage
session_id = @@SPID
Memory is directly or indirectly related to TempDb. As mentioned in introduction part of this article TempDb is used both for internal and user objects. Poor written query can cause high memory utilization which is one of the most common scenario while dealing with performance.
When rows comes from client they stores in memory, when memory is full then SQL will transfer the data on memory to TempDb to free the memory for new upcoming rows. When the data is needed it gets fetched from TempDb again which is a slower operation than reading the data from memory.
Usually, the problem occurs due to the long running transaction or bad cardinality estimator. The best way to solve it by building statistic but if still they don't work then changing the join type may help reducing the overhead on TempDb.
SQL Server cache temporary object like temporary tables, in memory. They will be cached under memory until
To check database level transaction related to TempDb; by below query we can get the list of transaction which are opened and consuming TempDb.
transaction_id ,
database_transaction_begin_time ,
DATEDIFF(
SECOND
, database_transaction_begin_time, GETDATE())
AS
'Transaction Time(Seconds)'
,
CASE
database_transaction_type
WHEN
1
THEN
'Read/write'
2
'Read-only'
3
'System'
END
'Type'
database_transaction_state
'The transaction has not been initialized.'
'The transaction is active.'
'The transaction has been initialized but has not generated any log records.'
4
'The transaction has generated log records.'
5
'The transaction has been prepared.'
10
'The transaction has been committed.'
11
'The transaction has been rolled back.'
12
'The transaction is being committed. In this state the log record is being generated, but it has not been materialized or persisted.'
'Description'
database_transaction_log_record_count
[Number
of
Log Records],
database_transaction_begin_lsn,
database_transaction_last_lsn,
database_transaction_most_recent_savepoint_lsn,
database_transaction_commit_lsn
sys.dm_tran_database_transactions
Trouble shooting TempDb issues are critical aspect of improving SQL Server performance. Below operators are solely dependent upon TempDb
There are several best practices which are recommended to be used for configuring and maintaining TempDb. These settings and configuration are recommended to be checked on regular interval.
TempDb data files have some basic thumb rules
You actually don't need to have files per core of CPU's. This means, that if you have 80 logical CPU's then you don't have to create 80 data files for TempDb. That will actually reduce performance.
Assume following parameters,
M = Space in GB available on your storage.
N = Number of data files needed
L = Number of log file needed
C = Number of logical CPU
From below query we can get the number of data files required. If N > 8 then we will start with 8 files & then gradually increase it based on the requirement and performance.
cpu_count/4
N
sys.dm_os_sys_info
Note: Do not start by creating more than 8 data files. You can increase it later if you observe TempDb contention. 8 is the general cap for MAXDOP setting.
Formula:
Number of data file(s) required (N) =C/4
Each data file size (W) = (M*.9)/ (N+2)
Log file size(X) =W*2
So, for example you have M = 100 GB and C = 12
Number of data file(s) required (N) =12/4=3
Each data file size (W) = (100*.9)/ (3+2) =18GB
Log file size(X) =18*2 = 36 GB
So, total size would be 3 * 18 + 36 = 90 GB and leave 10 GB for log file auto growth
This will help you to figure out the size requirement of data file and approximate log file size. However, log file size should also need more attention for proper functioning and based on available memory. Below section will cover the log file requirement for TempDb database.
Configuring Log files
Though, most of the operations are logged into TempDb & there is still variety of operation that does require TempDb like Temporary table, sorting etc. Log file is an important part of any database included TempDb. It is important to note that writing to log file is a sequential process and adding multiple log file doesn't work in parallel. This means that you can have 1 log file for TempDb [if it gets enough space to auto grow]
CHECKPOINT for TempDb has lower priority than other databases, i.e. it will fire when TempDb log is 70% filled. Now, if there is a long running transaction which has consumed 70% of log file but because TempDb checkpoint has lower priority so it will be queued behind databases checkpoint. This will cause in log file size keep on increasing. To avoid this, you can fire indirect CHECKPOINT when log file grow more than 80% which has higher priority.
There are few helpful tips to consider the size of TempDb log file
Project log file size = Estimated size of log file (E) + 10% E = n * (Number of minutes query executed) * (Row size)
So, if your temp data row size is 20 KB and it was executed for 30 min with 1000 rows per minute then your expected log file size will be = 1000 * 30 * 20 = 600000 KB ~ 585 MB + 58 MB = 643 MB
Note: Above formula is just a rough estimation there are other factors too which needs to be considered. Ex.: Parallel query executions, memory available on server, maximum memory allocation on SQL Server etc.
PAGELATCH_UP
CXPACKET
Below query will identify TempDb contention
sys.dm_os_waiting_tasks
resource_description
IN
(
'2:1:1'
'2:1:2'
'2:1:3'
)
AND
wait_type
Like
'PAGE%LATCH_%'
If there are large number of page latch for resource type 2:1:1 or 2:1:2 or 2:1:3 (i.e. database Id: File id: page number), this means that TempDb contention is happening due to one of the reasons
There are two ways to quickly remove database contention:
SUM
(user_object_reserved_page_count)*8
as
usr_obj_kb,
(internal_object_reserved_page_count)*8
internal_obj_kb,
(version_store_reserved_page_count)*8
version_store_kb,
(unallocated_extent_page_count)*8
freespace_kb,
(mixed_extent_page_count)*8
mixedextent_kb
sys.dm_db_file_space_usage
Attribute
Meaning
Higher number of user objects
More usage of Temp tables , cursors or temp variables
Higher number of internal objects
Query plan is using a lot of database. Ex: sorting, Group by etc.
Higher number of version stores
Long running transaction or high transaction throughput
Sp_WhoIsActive is a nice script to check which query is consuming your TempDb space. Alternatively, below query can provide a quick glance to the SQL text causing overhead on TempDb
TST.session_id
[Session Id],
EST.[text]
[SQL Query Text], [statement] =
COALESCE
NULLIF
SUBSTRING
EST.[text],
ER.statement_start_offset / 2,
ER.statement_end_offset < ER.statement_start_offset
0
ELSE
( ER.statement_end_offset - ER.statement_start_offset ) / 2
),
''
), EST.[text]),
DBT.database_transaction_log_bytes_reserved
[DB
Transaction
Log byte reserved]
, ER.Status
ER.TRANSACTION_ISOLATION_LEVEL
'UNSPECIFIED'
'READUNCOMITTED'
'READCOMMITTED'
'REPEATABLE'
'SERIALIZABLE'
'SNAPSHOT'
CAST
(ER.TRANSACTION_ISOLATION_LEVEL
VARCHAR
(32))
[
Isolation
Level
Name
],
QP.QUERY_PLAN
[XML Query Plan]
DBT
INNER
JOIN
sys.dm_tran_session_transactions
TST
ON
DBT.transaction_id = TST.transaction_id
LEFT
OUTER
sys.dm_exec_requests
ER
TST.session_id = ER.session_id
APPLY sys.dm_exec_sql_text(ER.plan_handle)
EST
CROSS
APPLY SYS.DM_EXEC_QUERY_PLAN(ER.PLAN_HANDLE) QP
DBT.database_id = 2;
Shrinking file is not recommended as it may fragment data and slow down your server performance. Even if you try to shrink data file it will only shrink user objects.
I would like to thank Olaf Helper MVP for reviewing this article.