FIX: The memory usage increases gradually when you frequently back up or restore a database in SQL Server 2008

Article translations Article translations
Article ID: 961323 - View products that this article applies to.
Bug #: 50003879 (SQL Hotfix)
Microsoft distributes Microsoft SQL Server 2008 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 2008 fix release.
Expand all | Collapse all

SYMPTOMS

When you frequently back up or restore a database in Microsoft SQL Server 2008, the memory usage increases gradually. Additionally, the size of the procedure cache grows at a steady rate.

You can see this problem by running the following statements.
SELECT p.plan_handle,
CONVERT (varchar, GETDATE(), 126) AS runtime, 
LEFT (p.cacheobjtype + ' (' + p.objtype + ')', 35) AS 
cacheobjtype,
p.usecounts, p.size_in_bytes / 1024 AS size_in_kb, 
stat.total_worker_time/1000 AS tot_cpu_ms, 
stat.total_elapsed_time/1000 AS tot_duration_ms, 
stat.total_physical_reads, 
stat.total_logical_writes, stat.total_logical_reads, 
LEFT (CASE WHEN pa.value=32767 THEN 'ResourceDb' 
ELSE ISNULL (DB_NAME (CONVERT (sysname, pa.value)), CONVERT 
(sysname,pa.value))
END, 40) AS dbname,
sql.objectid, 
CONVERT (nvarchar(50), CASE 
WHEN sql.objectid IS NULL THEN NULL 
ELSE REPLACE (REPLACE (sql.[text],CHAR(13), ' '), CHAR(10), '
')
END) AS procname, 
REPLACE (REPLACE (SUBSTRING (sql.[text], 
stat.statement_start_offset/2 + 1, 
CASE WHEN stat.statement_end_offset = -1 THEN LEN 
(CONVERT(nvarchar(max), sql.[text])) 
ELSE stat.statement_end_offset/2 - 
stat.statement_start_offset/2 + 1
END), CHAR(13), ' '), CHAR(10), ' ') AS stmt_text
FROM sys.dm_exec_cached_plans p 
OUTER APPLY sys.dm_exec_plan_attributes (p.plan_handle) pa 
INNER JOIN sys.dm_exec_query_stats stat ON p.plan_handle = 
stat.plan_handle 
OUTER APPLY sys.dm_exec_sql_text (p.plan_handle) AS sql
WHERE pa.attribute = 'dbid' 
ORDER BY p.plan_handle DESC
In the result, you may find that there are many records in which the values of the stmt_text column resemble the following:
select @media_set_id = media_set_id from msdb.dbo.backupmediaset where media_uuid = N'{7C5DCC4D-3065-47F3-AA5F-2C498DFF27F8}

insert msdb.dbo.backupmediaset (media_uuid, media_family_count, software_name, software_vendor_id, MTF_major_version, mirror_count, is_password_protected, is_compressed) values (N'{7C5DCC4D-3065-47F3-AA5F-2C498DFF27F8}', 1, @param0, 4608, 1, 1, 0, 1)

select @media_set_id = @@identity end select @media_count = media_count from msdb.dbo.backupmediafamily where media_set_id = @media_set_id and family_sequence_number = 1
These operations are the read operations and the write operations to the msdb backup history tables.

CAUSE

The procedure cache grows because the backup statements or the restore statements are not fully parameterized. Each statement results in a prepared statement in the cache that is never reused.

RESOLUTION

The fix for this issue was first released in Cumulative Update 3. For more information about how to obtain this cumulative update package for SQL Server 2008, click the following article number to view the article in the Microsoft Knowledge Base:
960484 Cumulative update package 3 for SQL Server 2008
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 2008 fix release. We recommend 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:
956909 The SQL Server 2008 builds that were released after SQL Server 2008 was released

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 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:
960484 Cumulative update package 3 for SQL Server 2008

REFERENCES

For more information about the list of builds that are available after the release of SQL Server 2008, click the following article number to view the article in the Microsoft Knowledge Base:
956909 The SQL Server 2008 builds that were released after SQL Server 2008 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 An Incremental Servicing Model is available from the SQL Server team to deliver hotfixes for reported problems
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 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 Description of the standard terminology that is used to describe Microsoft software updates

Properties

Article ID: 961323 - Last Review: January 19, 2009 - Revision: 1.0
APPLIES TO
  • Microsoft SQL Server 2008 Standard
  • Microsoft SQL Server 2008 Developer
  • Microsoft SQL Server 2008 Enterprise
  • Microsoft SQL Server 2008 Workgroup
Keywords: 
kbsurveynew kbhotfixrollup kbfix kbpubtypekc kbqfe kbexpertiseadvanced kbhotfixserver KB961323

Give Feedback

 

Contact us for more help

Contact us for more help
Connect with Answer Desk for expert help.
Get more support from smallbusiness.support.microsoft.com