DetailPage-MSS-KB

Microsoft small business knowledge base

Article ID: 947204 - Last Review: February 19, 2008 - Revision: 1.2

Bug #: 50002301 (SQL Hotfix)
Microsoft distributes Microsoft SQL Server 2005 fixes as one downloadable file. Because the fixes are cumulative, each new release contains all the hotfixes and all the security fixes that were included with the previous SQL Server 2005 fix release.

SYMPTOMS

In Microsoft SQL Server 2005, you run a query that creates internal objects in the tempdb database. When you run the query many times, the used space in the tempdb database increases continuously. Finally, the tempdb database becomes full. Additionally, you must restart the SQL Server service to clean up the tempdb database.

When this issue occurs, you run the following statement against the tempdb database many times.
SELECT SUM(internal_object_reserved_page_count) AS [internal object pages used],
(SUM(internal_object_reserved_page_count)*1.0/128) AS [internal object space in MB]
FROM sys.dm_db_file_space_usage;
If you do this, the value of the internal_object_reserved_page_count column increases every time that you run this statement.

Then, you query the sys.dm_db_session_space_usage dynamic management view. When you do this, the value of the internal_objects_alloc_page_count column increases without a corresponding increase in the value of the internal_objects_dealloc_page_count column.

CAUSE

Every time that you run the query, SQL Server creates the internal objects in the tempdb database. Under some conditions, SQL Server does not deallocate the pages that are allocated for the internal objects in the tempdb database.

RESOLUTION

The fix for this issue was first released in Cumulative Update 6. For more information about how to obtain this cumulative update package for SQL Server 2005 Service Pack 2, click the following article number to view the article in the Microsoft Knowledge Base:
946608  (http://support.microsoft.com/kb/946608/LN/ ) Cumulative update package 6 for SQL Server 2005 Service Pack 2
Note Because the builds are cumulative, each new fix release contains all the hotfixes and all the security fixes that were included with the previous SQL Server 2005 fix release. Microsoft recommends that you consider applying the most recent fix release that contains this hotfix. For more information, click the following article number to view the article in the Microsoft Knowledge Base:
937137  (http://support.microsoft.com/kb/937137/LN/ ) The SQL Server 2005 builds that were released after SQL Server 2005 Service Pack 2 was released
Microsoft SQL Server 2005 hotfixes are created for specific SQL Server service packs. You must apply a SQL Server 2005 Service Pack 2 hotfix to an installation of SQL Server 2005 Service Pack 2. By default, any hotfix that is provided in a SQL Server service pack is included in the next SQL Server service pack.

STATUS

Microsoft has confirmed that this is a problem in the Microsoft products that are listed in the "Applies to" section.

MORE INFORMATION

For more information about a complete list of the operations that use internal objects, visit the following Microsoft Web sites:
http://msdn2.microsoft.com/en-us/library/ms174412.aspx (http://msdn2.microsoft.com/en-us/library/ms174412.aspx)

http://technet.microsoft.com/en-us/library/cc966545.aspx (http://technet.microsoft.com/en-us/library/cc966545.aspx)
To determine the problematic session IDs (SPID) that allocate pages in the tempdb database, you can examine the allocation ring buffer. To do this, you must first enable trace flag 1106. By default, trace flag 1106 is not enabled. Then, you must run the following statement to display the allocation information and the deallocation information in the tempdb database.
SELECT 
record.value('(Record/@id)[1]', 'int') AS record_id,
CONVERT (varchar, DATEADD (ms, -1 * ((inf.cpu_ticks / inf.cpu_ticks_in_ms) - [timestamp]), GETDATE()), 126) AS EventTime,
[timestamp] ,
 record.value('(Record/@id)[1]', 'int') AS RingBuffer_Record_Id,
 record.value('(Record/ALLOC/Event)[1]', 'int') AS AllocationEventType,
 record.value('(Record/ALLOC/SpId)[1]', 'int') AS SpId,
 record.value('(Record/ALLOC/EcId)[1]', 'int') AS EcId,
 record.value('(Record/ALLOC/PageId)[1]', 'nvarchar(50)') AS AllocatedPageId,
 record.value('(Record/ALLOC/AuId)[1]', 'nvarchar(50)') AS AllocationUnitId,
 record.value('(Record/ALLOC/LsId)[1]', 'nvarchar(50)') AS LsId
FROM sys.dm_os_sys_info inf CROSS JOIN (
SELECT timestamp, CONVERT (xml, record) AS record 
FROM sys.dm_os_ring_buffers 
WHERE ring_buffer_type = 'RING_BUFFER_ALLOC_TRACE'
AND ( record LIKE '%<Event>23</Event>%' -- uniform extent allocation
OR record LIKE '%<Event>22</Event>%' -- uniform extent deallocation
OR record LIKE '%<Event>24</Event>%' -- mixed extent allocation
OR record LIKE '%<Event>25</Event>%' -- mixed extent deallocation
OR record LIKE '%<Event>10</Event>%' -- page allocation
OR record LIKE '%<Event>11</Event>%' -- page deallocation
)) AS t
    ORDER BY record.value('(Record/@id)[1]', 'int') ASC 
You can compare this information to the information from SQL Server Profiler to determine the queries that allocate pages and that do not deallocate pages in the tempdb database.

Note We recommend that you do not use trace flag 1106 on production servers because trace flag 1106 affects the performance of SQL Server.

For more information about what files are changed, and for information about any prerequisites to apply the cumulative update package that contains the hotfix that is described in this Microsoft Knowledge Base article, click the following article number to view the article in the Microsoft Knowledge Base:
946608  (http://support.microsoft.com/kb/946608/LN/ ) Cumulative update package 6 for SQL Server 2005 Service Pack 2

REFERENCES

For more information about the list of builds that are available after SQL Server Service Pack 2, click the following article number to view the article in the Microsoft Knowledge Base:
937137  (http://support.microsoft.com/kb/937137/LN/ ) The SQL Server 2005 builds that were released after SQL Server 2005 Service Pack 2 was released
For more information about the Incremental Servicing Model for SQL Server, click the following article number to view the article in the Microsoft Knowledge Base:
935897  (http://support.microsoft.com/kb/935897/LN/ ) An Incremental Servicing Model is available from the SQL Server team to deliver hotfixes for reported problems
For more information about how to obtain SQL Server 2005 Service Pack 2, click the following article number to view the article in the Microsoft Knowledge Base:
913089  (http://support.microsoft.com/kb/913089/LN/ ) How to obtain the latest service pack for SQL Server 2005
For more information about the new features and the improvements in SQL Server 2005 Service Pack 2, visit the following Microsoft Web site:
http://go.microsoft.com/fwlink/?LinkId=71711 (http://go.microsoft.com/fwlink/?LinkId=71711)
For more information about the naming schema for SQL Server updates, click the following article number to view the article in the Microsoft Knowledge Base:
822499  (http://support.microsoft.com/kb/822499/LN/ ) New naming schema for Microsoft SQL Server software update packages
For more information about software update terminology, click the following article number to view the article in the Microsoft Knowledge Base:
824684  (http://support.microsoft.com/kb/824684/LN/ ) Description of the standard terminology that is used to describe Microsoft software updates

APPLIES TO
  • Microsoft SQL Server 2005 Standard Edition
  • Microsoft SQL Server 2005 Developer Edition
  • Microsoft SQL Server 2005 Enterprise Edition
  • Microsoft SQL Server 2005 Standard X64 Edition
  • Microsoft SQL Server 2005 Standard Edition for Itanium-based Systems
  • Microsoft SQL Server 2005 Enterprise X64 Edition
  • Microsoft SQL Server 2005 Enterprise Edition for Itanium-based Systems
Keywords: 
kbsql2005engine kbhotfixrollup kbfix kbpubtypekc kbqfe kbexpertiseadvanced KB947204
Share
Additional support options
Ask The Microsoft Small Business Support Community
Contact Microsoft Small Business Support
Find Microsoft Small Business Support Certified Partner
Find a Microsoft Store For In-Person Small Business Support