This is the third post this week on querying the SQL Agent Job tables to return data not included in the GUI.

SQL Server Agent has a lot of great information stored away in the system tables, and though the GUI provides some interesting views of the data, it is necessary to roll your sleeves up and get querying the tables yourself. All pertinent tables are in the dbo schema in the msdb database, so querying for the data quite straightforward.

This week I am posting a query a day that I have written to get the average duration of the jobs run. The real kicker about getting this information is the run_duration column in the sysjobhistory table: the column itself is an int, so it takes a fair bit of data manipulation to retrieve the data in an accurate and legible format.

The first query returns the jobs by average duration. With this information you can then scroll through the history of a job in the GUI to see if any were significantly higher or lower than average. The next step in this query would be to return any jobs and the dates where the duration was significantly higher than the average. The RedGate Monitor Tool has such a feature, and it is quite handy.

-- avg duration by date including number of runs
SELECT job_name = rs.NAME
	,totes = NumberOfRuns
	,RunDate = rs.run_date
	,avg_ss = rd
	,avg_hhmmss = CONVERT(CHAR(8), DATEADD(second, rd, 0), 108)
FROM (
	SELECT j.NAME
		,h.run_date
		,COUNT(*) AS NumberOfRuns
		,rd = AVG(DATEDIFF(SECOND, 0, STUFF(STUFF(RIGHT('000000' + CONVERT(VARCHAR(6), run_duration), 6), 5, 0, ':'), 3, 0, ':')))
	FROM msdb.dbo.sysjobhistory h
	INNER JOIN msdb.dbo.sysjobs AS j ON h.job_id = j.job_id
	WHERE h.step_id = 0
		AND CONVERT(DATETIME, convert(CHAR(8), h.run_date)) > DATEADD(DAY, - 7, GETDATE())
	GROUP BY j.NAME
		,h.run_date
	) AS rs
ORDER BY job_name
	,RunDate DESC