You are currently offline, waiting for your internet to reconnect

FIX: The Management Data Warehouse database grows very large after you enable the Data Collector feature in SQL Server 2008

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.
SYMPTOMS
In Microsoft SQL Server 2008, after you enable the Data Collector feature, the Management Data Warehouse database grows very large and may exhaust your disk space.

Additionally, if you run the following queries, you find many orphan rows in the snapshots.notable_query_plan or snapshots.notable_query_text tables:
SELECT COUNT(*)FROM snapshots.notable_query_plan AS qp         WHERE NOT EXISTS (            SELECT *             FROM snapshots.query_stats AS qs            WHERE qs.[sql_handle] = qp.[sql_handle] AND qs.plan_handle = qp.plan_handle                 AND qs.plan_generation_num = qp.plan_generation_num                 AND qs.statement_start_offset = qp.statement_start_offset                 AND qs.statement_end_offset = qp.statement_end_offset                 AND qs.creation_time = qp.creation_time);
SELECT COUNT(*)FROM snapshots.notable_query_text AS qtWHERE NOT EXISTS (            SELECT *             FROM snapshots.query_stats AS qs            WHERE qs.[sql_handle] = qt.[sql_handle]);
CAUSE
The generic deletion process deletes the data that corresponds to a specific snapshot ID. However, the query plan rows and the query text rows do not correspond to a specific snapshot ID. Therefore, these rows are not deleted by the generic deletion process.
RESOLUTION

SQL Server 2008

Important You must use this fix if you are running the release version of SQL Server 2008.

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 2008, click the following article number to view the article in the Microsoft Knowledge Base:
971490 Cumulative update package 6 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

SQL Server 2008 Service Pack 1

Important You must use this fix if you are running SQL Server 2008 Service Pack 1.

The fix for this issue was first released in Cumulative Update 4 for SQL Server 2008 Service Pack 1. For more information about this cumulative update package, click the following article number to view the article in the Microsoft Knowledge Base:
973602 Cumulative update package 4 for SQL Server 2008 Service Pack 1
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. 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:
970365 The SQL Server 2008 builds that were released after SQL Server 2008 Service Pack 1 was released
Microsoft SQL Server 2008 hotfixes are created for specific SQL Server service packs. You must apply a SQL Server 2008 Service Pack 1 hotfix to an installation of SQL Server 2008 Service Pack 1. By default, any hotfix that is provided in a SQL Server service pack is included in the next SQL Server service pack.
WORKAROUND
To work around this problem, use the following scripts in the Management Data Warehouse database to delete these orphan rows:
-- Purge snapshots.notable_query_plan table DECLARE @delete_batch_size bigint;    DECLARE @rows_affected int;    SET @delete_batch_size = 500;    SET @rows_affected = @delete_batch_size;    WHILE (@rows_affected = @delete_batch_size)    BEGIN        DELETE TOP (@delete_batch_size) snapshots.notable_query_plan         FROM snapshots.notable_query_plan AS qp         WHERE NOT EXISTS (            SELECT *             FROM snapshots.query_stats AS qs            WHERE qs.[sql_handle] = qp.[sql_handle] AND qs.plan_handle = qp.plan_handle                 AND qs.plan_generation_num = qp.plan_generation_num                 AND qs.statement_start_offset = qp.statement_start_offset                 AND qs.statement_end_offset = qp.statement_end_offset                 AND qs.creation_time = qp.creation_time);        SET @rows_affected = @@ROWCOUNT;        RAISERROR ('Deleted %d orphaned rows from snapshots.notable_query_plan', 0, 1, @rows_affected) WITH NOWAIT;    END;    -- Purge snapshots.notable_query_text table    SET @rows_affected = @delete_batch_size;    WHILE (@rows_affected = @delete_batch_size)    BEGIN        DELETE TOP (@delete_batch_size) snapshots.notable_query_text         FROM snapshots.notable_query_text AS qt        WHERE NOT EXISTS (            SELECT *             FROM snapshots.query_stats AS qs            WHERE qs.[sql_handle] = qt.[sql_handle]);        SET @rows_affected = @@ROWCOUNT;        RAISERROR ('Deleted %d orphaned rows from snapshots.notable_query_text', 0, 1, @rows_affected) WITH NOWAIT;    END;
STATUS
Microsoft has confirmed that this is a problem in the Microsoft products that are listed in the "Applies to" section.
REFERENCES
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:
822499New 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: 970014 - Last Review: 07/21/2009 01:09:51 - Revision: 1.1

Microsoft SQL Server 2008 Standard, Microsoft SQL Server 2008 Enterprise, Microsoft SQL Server 2008 Developer, Microsoft SQL Server 2008 Workgroup

  • kbsurveynew kbexpertiseadvanced kbqfe kbfix KB970014
Feedback