Symptoms
When the tempdb database is heavily used, SQL Server may experience contention when it tries to allocate pages.
From the sysprocesses system table output, the waitresource may show up as "2:1:1" (PFS Page) or "2:1:3" (SGAM Page). Depending on the degree of contention, this may also lead to SQL Server appearing unresponsive for short periods. These operations heavily use tempdb:-
Repeated create and drop of temporary tables (local or global).
-
Table variables that use tempdb for storage purposes.
-
Work tables associated with CURSORS.
-
Work tables associated with an ORDER BY clause.
-
Work tables associated with an GROUP BY clause.
-
Work files associated with HASH PLANS.
Heavy and significant use of these activities may lead to the contention problems.
Cause
During object creation, two (2) pages must be allocated from a mixed extent and assigned to the new object. One page is for the Index Allocation Map (IAM), and the second is for the first page for the object. SQL Server tracks mixed extents by using the Shared Global Allocation Map (SGAM) page. Each SGAM page tracks about 4 gigabytes of data.
As part of allocating a page from the mixed extent, SQL Server must scan the Page Free Space (PFS) page to find out which mixed page is free to be allocated. The PFS page keeps track of free space available on every page, and each PFS page tracks about 8000 pages. Appropriate synchronization is maintained to make changes to the PFS and SGAM pages; and that can stall other modifiers for short periods. When SQL Server searches for a mixed page to allocate, it always starts the scan on the same file and SGAM page. This results in intense contention on the SGAM page when several mixed page allocations are underway, which can cause the problems documented in the "Symptoms" section of this article. Note De-allocation activities must also modify the pages, which can contribute to the increased contention. To learn more about the different allocation mechanisms used by SQL Server (SGAM, GAM, PFS, IAM), see the "References" section of this article.Resolution
Microsoft SQL Server 2000
To reduce the allocation resource contention for a tempdb that is experiencing heavy usage, follow all these steps:
-
Apply Service Pack 4 for Microsoft SQL Server 2000. SQL Server 2000 Service Pack 4 (SP4) is available at the following Microsoft Web site:http://www.microsoft.com/download/details.aspx?FamilyId=8E2DFC8D-C20E-4446-99A9-B7F0213F8BC5 For additional information, click the following article number to view the article in the Microsoft Knowledge Base:
290211 How to obtain the latest SQL Server 2000 service pack
-
Implement trace flag -T1118.
-
Increase the number of data files in tempdb to maximize disk bandwidth and to reduce contention in allocation structures. As a general rule, if the number of logical processors is less than 8 or equal to 8, use the same number of data files as logical processors. If the number of logical processors is greater than 8, use 8 data files and then if contention continues, increase the number of data files by multiples of 4 (up to the number of logical processors) until the contention is reduced to acceptable levels or make changes to the workload/code.
Note These steps also apply to Microsoft SQL Server 7.0. The only exception is that there is no hotfix for SQL Server 7.0; therefore, step 1 does not apply.
With regard to step 2, the use of trace flag -T1118 for Microsoft SQL Server 7.0, before you use the trace flag, see the following article in the Microsoft Knowledge Base:813492 FIX: Create index fails on SQL Server 7.0 when trace flag 1118 is enabled
Microsoft SQL Server 2005 and later versions
To reduce the allocation resource contention for a tempdb that is experiencing heavy usage, follow these steps:
-
Implement trace flag -T1118.
-
Increase the number of data files in tempdb to maximize disk bandwidth and to reduce contention in allocation structures. As a general rule, if the number of logical processors is less than or equal to 8, use the same number of data files as logical processors. If the number of logical processors is greater than 8, use 8 data files and then if contention continues, increase the number of data files by multiples of 4 (up to the number of logical processors) until the contention is reduced to acceptable levels or make changes to the workload/code.
More Information
How the fix in SQL 2000 SP4 and later versions reduces contention
SQL Server 2000 Sp4 and later versions have a fix that introduces a round-robin algorithm for mixed page allocations. With the fix, the starting file will now be different for each consecutive mixed page allocation (if more than one file exists). This avoids the contention problem by breaking up the train that went through the SGAMs in the same order every time with the same starting point. The new allocation algorithm for SGAM is pure round-robin, and does not honor the proportional fill to maintain speed. Microsoft recommends that you create the tempdb data files with the same size.
How implementing trace flag -T1118 reduces contention
Here is list of how use of -T1118 reduces contention:
-
-T1118 is a server-wide setting.
-
Include the -T1118 trace flag in the Startup parameters for SQL Server so that the trace flag remains in effect even after SQL Server is recycled.
-
-T1118 removes almost all single page allocations on the server.
-
By disabling most of the single page allocations, you reduce the contention on the SGAM page.
-
With -T1118 turned ON, almost all new allocations are performed from a GAM page (for example, 2:1:2) that allocates eight (8) pages (1 extent) at a time to a object as opposed to a single page from an extent for the first eight (8) pages of an object, without the trace flag.
-
The IAM pages still use the single page allocations from the SGAM page, even with -T1118 turned ON. However, when combined with hotfix 8.00.0702 and increased tempdb data files, the net effect is a reduction in contention on the SGAM page. For space concerns, see the "Disadvantages" section of this article.
Increase the number of tempdb data files with equal sizing
If the data file size of tempdb is 5 GB, and the Log file size is 5 GB, the recommendation is to increase the single datafile to 10 (each of 500 MB to maintain equal sizing), and leave the log file as is. Having the different data files on separate disks would be good. However, this is not required and they can co-exist on the same disk. The optimal number of tempdb data files depends on the degree of contention seen in tempdb. As a starting point, you can configure the tempdb to be at least equal to the number of processors assigned for SQL Server. For higher end systems (for example, 16 or 32 proc), the starting number could be 10. If the contention is not reduced, you may have to increase the number of data files more. Note A dual-core processor is considered to be two processors. The equal sizing of data files is critical because the proportional fill algorithm is based on the size of the files. If data files are created with unequal sizes, the proportional fill algorithm tries to use the largest file more for GAM allocations instead of spreading the allocations between all the files, thereby defeating the purpose of creating multiple data files. The auto-grow of tempdb data files can also interfere with the proportional fill algorithm. Therefore, it may be a good idea to turn off the auto-grow feature for the tempdb data files. If the auto-grow option is turned off, you must make sure to create the data files so that they are large enough to prevent the server from experiencing a lack of disk space with tempdb.
How increasing the number of tempdb data files with equal sizing reduces contention
Here is a list of how increasing the number of tempdb data files with equal sizing reduces contention:
-
With one data file for the tempdb, you only have one GAM page, and one SGAM page for each 4 GB of space.
-
Increasing the number of data files with the same sizes for
tempdb effectively creates one or more GAM and SGAM pages for each data file. -
The allocation algorithm for GAM gives out one extent at a time (eight contiguous pages) from the number of files in a round robin fashion while honoring the proportional fill. Therefore, if you have 10 equal sized files, the first allocation is from File1, the second from File2, the third from File3, and so on.
-
The resource contention of the PFS page is reduced because eight pages are marked as FULL at a time because GAM is allocating the pages.
Disadvantages
The only downside to the recommendations mentioned earlier is that you may see the size of the databases increase when the following conditions are true:
-
New objects are created in a user database.
-
Each of the new objects occupy less than 64 KB of storage.
If these conditions are true, you may allocate 64 KB ( 8 pages * 8 KB = 64 KB ) for an object that only requires 8 KB of space, thus wasting 56 KB of storage. However, if the new object uses more than 64 KB (8 pages) in it's lifetime, there is no downside with the trace flag. Therefore, in a worst case scenario, SQL Server may end up allocating seven (7) additional pages during the first allocation only for new objects that never grow beyond one (1) page.
References
For more information about GAM, SGAM, PFS, and IAM, see the following SQL Server 2000 Books Online topics:
-
"Managing Space Used by Objects"
-
"Managing Extent Allocations and Free Space"
-
"Table and Index Architecture"
-
"Heap Structures"
Additional referenceshttp://technet.microsoft.com/en-us/library/cc966545.aspx For more information about tempdb database files and Trace Tlag 1118, visit the following MSDN website:http://blogs.msdn.com/b/psssql/archive/2009/06/04/sql-server-tempdb-number-of-files-the-raw-truth.aspx For more information about how to use Trace Flag 1118 in SQL Server 2005 and SQL Server 2008, visit the following MSDN website:http://blogs.msdn.com/b/psssql/archive/2008/12/17/sql-server-2005-and-2008-trace-flag-1118-t1118-usage.aspx For more information about how to monitor and troubleshoot allocation bottlenecks in the tempdb database, visit the following MSDN website:http://blogs.msdn.com/b/sqlserverstorageengine/archive/2009/01/11/tempdb-monitoring-and-troubleshooting-allocation-bottleneck.aspx
For more information about the tempdb database in SQL Server 2005, visit the following MSDN website: