Dec
27
2012

MSDB database is growing due to sysmaintplan_logdetail table!

Today found an issue where MSDB database size was 4GB and the table which was utilizing more space is sysmaintplan_logdetail, now to fix it first identified the number of records present in table and the oldest dated, then deleted and truncated the maintenance plan history to clear those records, please find how all this is achieved using troubleshooting steps below,

 

Troubleshooting Steps:

1. First connect SQL Server via SSMS, then go to MSDB database > right click > Reports > Standard Reports > Disk space usage by top tables

 

It will fetch you data that which table is occupying more space as below,

 

2. In my case the max size was occupied by sysmaintplan_logdetail table, (note below the number of records are 228, these were in lakhs which I truncated following option give in below points),

 

 

3. Now if you see the number of records high, then first run below query and find out the records before particular date so that you won’t land up in filling up log space while deleting records, delete in batches, (If you just want to truncate table without going through delete process, directly go to Step 6, your job would be done in 5 secs)

 

select
count(start_time)
from sysmaintplan_logdetail with (nolock) where start_time <
‘4/28/2009’

–modify date and table name as per your requirement

 

4. Now run truncate command to remove history as,

sp_maintplan_delete_log @oldest_time=‘4/28/2009’

–modify date as per your requirement

 

Note: If you want to delete backup history then use following command, sp_delete_backuphistory @oldest_date=‘4/28/2009’

 

5. Run dbcc updateusage
(‘msdb’)
to update database usage

 

6. In my case, even after deleting data, it didn’t release space, all space is showing as reserved, so I did following to release space,

As per articles,

http://sqlserverpedia.com/blog/sql-server-bloggers/resolving-very-large-msdb/

http://social.msdn.microsoft.com/forums/en-US/sqldatabaseengine/thread/d81fe528-5ce5-4d31-b758-01e716bd0ec8/

 

Ran following script to truncate sysmaintplan_logdetail table and it worked!

 

ALTER
TABLE [dbo].[sysmaintplan_log] DROP
CONSTRAINT [FK_sysmaintplan_log_subplan_id];

ALTER
TABLE [dbo].[sysmaintplan_logdetail] DROP
CONSTRAINT [FK_sysmaintplan_log_detail_task_id];

truncate
table msdb.dbo.sysmaintplan_logdetail;

truncate
table msdb.dbo.sysmaintplan_log;

ALTER
TABLE [dbo].[sysmaintplan_log] WITH
CHECK
ADD
CONSTRAINT [FK_sysmaintplan_log_subplan_id] FOREIGN
KEY([subplan_id])

REFERENCES [dbo].[sysmaintplan_subplans]
([subplan_id]);

ALTER
TABLE [dbo].[sysmaintplan_logdetail] WITH
CHECK
ADD
CONSTRAINT [FK_sysmaintplan_log_detail_task_id] FOREIGN
KEY([task_detail_id])

REFERENCES [dbo].[sysmaintplan_log]
([task_detail_id]) ON

DELETE
CASCADE;

 

After executing above, don’t forget to shrink your database via GUI or running below script,

— SHRINK THE MSDB LOG FILE

USE MSDB

GO

DBCC SHRINKFILE(MSDBLog, 100)

GO

— SHRINK THE MSDB Data File

USE MSDB

GO

DBCC SHRINKFILE(MSDBData, 100)

GO

 

To avoid recurrence of the issue, set a maintenance plan to delete history or restrict the maintenance records to some limit like 10000.

 

Hope it helps!

Download PDF

About the Author: Nitin G

Indian born, trekker, biker, photographer, lover of monsoons. I've been working full time with SQL Server since year 2005 and blogs to post the content aquired during my research on new topics or fixing issues faced by me as a DBA while working in different kind of projects, hope some of my posts may helps others in SQLDBA community. Everything you read on my blog is my own personal opinion and any code is provided "AS-IS" with no warranties!

7 Comments + Add Comment

  • Thanks Nitin G!
    it realy works fine.

    Youre the Man!!

  • This worked for me. I had a msdb.mdf that was 86GB. Now its down to 100 MB.

  • This helped out immensely. Thanks for writing it! It was the first link when googling msdb sysmaintplan_logdetail

    • Thanks Craig for comment, good to hear that it worked for you!

  • Worked like a charm. First hit on googling sysmaintplan_logdetail.

    Please note that you’re using smart quotes and m-dashes for comments in your script. SSMS doesn’t like those. For the rest perfect!

    • Thanks William that it worked, will work on the better script coding or posting with some additional plug-in 🙂

  • Thank you for sharing this, really appreciate it. Was able to reduce my MSDB from 400GB to a much more manageable size. Now time to check what is going on with the maintenance.

Leave a comment

Subscribe to this blog via Email

Enter your email address to subscribe to this blog and receive notifications of new posts by email.

Join 34 other subscribers

Translate this blog!

EnglishFrenchGermanItalianPortugueseRussianSpanish

Calender

December 2017
M T W T F S S
« Nov    
 123
45678910
11121314151617
18192021222324
25262728293031

View Post by Categories

%d bloggers like this: