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/
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!

7 Comments + Add Comment
Leave a comment
Subscribe to this blog via Email
Old Posts
- November 2017 (3)
- October 2017 (4)
- September 2017 (2)
- May 2017 (1)
- April 2017 (1)
- July 2016 (3)
- May 2016 (1)
- April 2016 (1)
- February 2016 (2)
- January 2016 (1)
- October 2015 (1)
- September 2015 (1)
- August 2015 (1)
- July 2015 (2)
- June 2015 (3)
- April 2015 (1)
- March 2015 (1)
- December 2014 (1)
- September 2014 (2)
- April 2014 (1)
- January 2014 (3)
- October 2013 (2)
- September 2013 (2)
- August 2013 (4)
- July 2013 (1)
- June 2013 (2)
- May 2013 (5)
- April 2013 (3)
- March 2013 (1)
- February 2013 (9)
- January 2013 (11)
- December 2012 (14)
- November 2012 (3)
- October 2012 (4)
- July 2012 (2)
- June 2012 (3)
- May 2012 (2)
- April 2012 (8)
- March 2012 (6)
- February 2012 (3)
- January 2012 (1)
- December 2011 (5)
- November 2011 (8)
- October 2011 (5)
- September 2011 (3)
- August 2011 (3)
- July 2011 (3)
- May 2011 (1)
- November 2010 (1)
Tags
Calender
M | T | W | T | F | S | S |
---|---|---|---|---|---|---|
« Nov | ||||||
1 | 2 | 3 | 4 | |||
5 | 6 | 7 | 8 | 9 | 10 | 11 |
12 | 13 | 14 | 15 | 16 | 17 | 18 |
19 | 20 | 21 | 22 | 23 | 24 | 25 |
26 | 27 | 28 | 29 | 30 |
View Post by Categories
Recent Articles
- Setting up Always ON Availability Group in Multi Subnet Cluster – Recommendations
- Configuring Replication with Always ON Availability Group
- Login failed for user ‘DOMAIN\COMPUTER$’. Reason: Could not find a login matching the name provided. [CLIENT: ]
- Modern Servicing Model (Service Pack and Cumulative Updates) for SQL Server 2017 and onwards
- Fix: SSMS 2012 opening Debug window when pressing F5
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.