Tag Archives: delete

How to delete all SQL Server Jobs that have no maintenance plan with T-Sql

I’d really recommend not running the output of this script on a live environment! This is just a little something I whipped up to clear out a development environment.

Running the script will output the T-Sql required to deleted all jobs on the SQL Server instance. Jobs for maintenance plans are not included as maintenance plans need to be deleted first. Just copy the text and paste into a new SSMS window and execute. You could change the PRINT to EXEC but I wouldn’t recommend it. 

SET NOCOUNT ON

DECLARE @Job TABLE (JobName SYSNAME)
DECLARE @JobName AS SYSNAME
DECLARE @Sql AS VARCHAR(MAX)

SET @JobName = ''

INSERT INTO @Job (JobName)
SELECT j.Name
FROM msdb.dbo.sysjobs AS j
LEFT JOIN msdb.dbo.sysmaintplan_subplans AS p ON j.job_id = p.job_id
WHERE p.subplan_id IS NULL
ORDER BY j.Name ASC

WHILE @JobName IS NOT NULL
BEGIN
	SET @JobName = (
			SELECT MIN(JobName)
			FROM @Job
			WHERE JobName > @JobName
			)
	SET @Sql = '
EXEC msdb.dbo.sp_delete_job @job_name = ' + '''' + @JobName + '''' + '; 
'
	PRINT @Sql
END

How to clear SQL Server backup and job history

SQL Server makes a record of each backup and restore it performs. This information is recorded across the following tables:

msdb.dbo.backupfile
msdb.dbo.backupfilegroup
msdb.dbo.backupmediafamily
msdb.dbo.backupmediaset
msdb.dbo.backupset
msdb.dbo.restorefile
msdb.dbo.restorefilegroup
msdb.dbo.restorehistory

There is no cleanup process that automatically clears these records down so as you can imagine over time it could grow to be substantial.

Before you upgrade a SQL Server instance if any of these tables exceeds 10,000 rows this can cause an upgrade to hang so it is recommended the older records be deleted.

To reduce rows in all of these tables, you can run the sp_delete_backuphistory stored procedure. This procedure deletes the entries in all of the backup and restore history tables for backup sets older than a specified date. An example is shown below:

EXEC msdb..sp_delete_backuphistory ‘20161201 12:00:00.000’

Similarly to remove records from msdb.dbo.sysjobhistory you can run the following example as shown below:

EXEC msdb..sp_purge_jobhistory @oldest_date = ‘20161201 12:00:00.000’

It is recommended you set up a job to clear these tables however how often you clear them requires some thought. For instance you may want to keep, or archive, the job history for performance comparisons over time or as a record of job failures.

Another example is I use a stored procedure that automatically generates TSQL to perform restores. This stored procedure uses the records in the backup history tables to generate the TSQL. Therefore I need to be careful I do not delete records that are within our backup file retention time period otherwise I would not be able to generate a restore script for those backup files using the stored procedure.

You might be reliant on these tables as well in some way so keep this in mind.