SQL Server Management Studio has a built-in Job Activity monitor available under the SQL Server Agent folder in SSMS. This provides a neat dialog window for easy access to all-you-need-to know about your jobs. One can also run the T-SQL command EXEC msdb.dbo.sp_help_jobactivity
; to get job status. These cover statistics, statuses, categories, scheduled times and in-depth results of job executions.
From time to time, handling couple of jobs is not a problem. However, it might become a problem when the number of jobs exceeds a manageable number in terms of job execution times, scheduled runs and job outcomes. The job history monitor report is a quick solution for getting general overview of your job history in graphical outcome using all the advantages of Reporting Services (SSRS). The report was prepared for monitoring the concurrent job execution and getting full overview of current situation on job activities. It can be used by DBAs, resource monitoring people, system analysts and even middle management as part of Microsoft Sharepoint implementation.
The query underneath the report is mainly constructed from three major parts worth taking a closer look for better understanding of the report.
Part A
Part A is a general query for retrieving job history from system tables msdb.dbo.sysjobhistory and msdb.dbo.sysjobs. Query returns results for current day (day of execution) and does some general string conversions and calculations.
SELECT h.job_id ,j.name ,CAST( SUBSTRING(CONVERT(VARCHAR(10),h.run_date) , 5,2) +'-' + SUBSTRING(CONVERT(VARCHAR(10),h.run_date) , 7,2) +'-' + SUBSTRING(CONVERT(VARCHAR(10),h.run_date),1,4) + ' ' + + SUBSTRING(CONVERT(VARCHAR(10),replicate('0',6-len(h.run_time)) + CAST(h.run_time AS VARCHAR)), 1, 2) + ':' + SUBSTRING(CONVERT(VARCHAR(10),replicate('0',6-len(h.run_time)) + CAST(h.run_time AS VARCHAR)), 3, 2) + ':' + SUBSTRING(CONVERT(VARCHAR(10),replicate('0',6-len(h.run_time)) + CAST(h.run_time AS VARCHAR)), 5, 2) AS SMALLDATETIME) AS JobStart ,DATEADD(SECOND, CASE WHEN h.run_duration > 0 THEN (h.run_duration / 1000000) * (3600 * 24) + (h.run_duration / 10000 % 100) * 3600 + (h.run_duration / 100 % 100) * 60 + (h.run_duration % 100) ELSE 0 END,CAST( SUBSTRING(CONVERT(VARCHAR(10),h.run_date) , 5,2) +'-' + SUBSTRING(CONVERT(VARCHAR(10),h.run_date) , 7,2) +'-' + SUBSTRING(CONVERT(VARCHAR(10),h.run_date),1,4) + ' ' + + SUBSTRING(CONVERT(VARCHAR(10),replicate('0',6-len(h.run_time)) + CAST(h.run_time AS VARCHAR)), 1, 2) + ':' + SUBSTRING(CONVERT(VARCHAR(10),replicate('0',6-len(h.run_time)) + CAST(h.run_time AS VARCHAR)), 3, 2) + ':' + SUBSTRING(CONVERT(VARCHAR(10),replicate('0',6-len(h.run_time)) + CAST(h.run_time AS VARCHAR)), 5, 2) AS SMALLDATETIME)) AS JobEND ,outcome = CASE WHEN h.run_status = 0 THEN 'Fail' WHEN h.run_status = 1 THEN 'Success' WHEN h.run_status = 2 THEN 'Retry' WHEN h.run_status = 3 THEN 'Cancel' WHEN h.run_status = 4 THEN 'In progress' END FROM sysjobhistory AS h JOIN sysjobs AS j on j.job_id = h.job_id WHERE h.step_id = 0 AND j.enabled = 1 AND CAST(SUBSTRING(CONVERT(VARCHAR(10),h.run_date) , 5,2) +'-' + SUBSTRING(CONVERT(VARCHAR(10),h.run_date) , 7,2) +'-' + SUBSTRING(CONVERT(VARCHAR(10),h.run_date),1,4) AS SMALLDATETIME) = CONVERT(VARCHAR(10), GETDATE(), 121)
Part B
Part B generated and prepares the time frame. For purpose of Job history monitor report, 5 minutes time (300 seconds) interval was used. And system table master.dbo.spt_values was used as pre-prepared tally table.
SELECT v.number ,DATEADD(SECOND,300*v.number,DATEDIFF(dd,0,GETDATE())) AS timeInterval_FROM ,DATEADD(SECOND,300*v.number+299,DATEDIFF(dd,0,GETDATE())) AS timeInterval_to FROM master.dbo.spt_values AS v WHERE v.type = 'P' AND v.number <= 288
Part C
Part C generates empty rows for continuous presentation of time table used later in SSRS. It refers to previously generated part B and adds all missing 5 minutes intervals (or any other desired time interval), and creating actual time flow of a job executions on real time scale. In this part 5 minutes intervals are used again so we keep consistency throughout the query.
-- Data "imputation" of empty rows for all jobs. -- To appear in SSRS as a continous block, when job is running for more than 5 minutes SELECT DATEADD(SECOND,300*s.number,DATEDIFF(dd,0,GETDATE())) AS TimeInterval ,a.JobName ,a.outcome FROM ( SELECT a.JobName ,a.outcome ,a.jobStart ,MIN(a.TimeInterval) AS minTI ,MAX(a.TimeInterval) AS maxTI FROM timeset AS a GROUP BY a.JobName ,a.outcome ,a.jobStart ) AS a INNER JOIN master.dbo.spt_values AS s ON DATEADD(SECOND,300*s.number,DATEDIFF(dd,0,GETDATE())) BETWEEN a.minTI AND a.maxTI WHERE s.type = 'P' AND s.number <= 288 ORDER BY TimeInterval; GO
Creating report
The query is copied to SSRS and we create a general matrix in the Report designer. We show the time interval in the first column with the jobs in rows.
For better readability of the matrix, some additional conditional formatting is introduced on field [outcome]. The colours of job outcome correspond to definition of job outcome introduced in Part A in select list as field {outcome}.
Executing report
Once the look of the report is finished, it is built and deployed to your reporting manager TargetServerURL. The report will come out like this:
A 25% Zoom is used intentionally to stress the graphical overview of the report. The sample picture holds a minimum of 25 different job outcomes. One can immediately see concurrent jobs running and their approximate length (remember we used 5 minutes interval; each cell represents 5 minutes). The far left is the timeline continuing with all jobs (in this sample, jobs are sorted alphabetically). The colours denote the job results as prepared in report builder with the SWITCH command.
Customizing query and report
A quick guide on how to customize the query. If 1 minute (or any other desired time frame will be used; e.g.: 30 minutes) is what you need, two changes are needed.
In code Part B, under point (1) 300 seconds should be changed to 60 seconds (when 1 minute interval will be used) and under point (2) 288 should be changed to 1440. Point (2) is literally number of minutes per hour. 1 day = 1minute* 1440 intervals (1 day = 1440 minutes); creating 1 minute timeframe. 1 day= 5 minutes*288 intervals (1 day = 5*288 minutes). 10 minute interval would mean 144 intervals. Respectively.
SELECT v.number /* POINT (1) */ ,DATEADD(SECOND,60*v.number,DATEDIFF(dd,0,GETDATE())) AS timeInterval_FROM ,DATEADD(SECOND,60*v.number+59,DATEDIFF(dd,0,GETDATE())) AS timeInterval_to FROM master.dbo.spt_values AS v WHERE v.type = 'P' /* POINT (2) */AND v.number <= 1440
The same time alterations are applied to the code in Part C.
SELECT /* POINT (1) */ DATEADD(SECOND,60*s.number,DATEDIFF(dd,0,GETDATE())) AS TimeInterval ,a.JobName ,a.outcome FROM ( SELECT a.JobName ,a.outcome ,a.jobStart ,MIN(a.TimeInterval) AS minTI ,MAX(a.TimeInterval) AS maxTI FROM timeset AS a GROUP BY a.JobName ,a.outcome ,a.jobStart ) AS a INNER JOIN master.dbo.spt_values AS s /* POINT (2) */ ON DATEADD(SECOND,60*s.number,DATEDIFF(dd,0,GETDATE())) BETWEEN a.minTI AND a.maxTI WHERE s.type = 'P' /* POINT (3) */AND s.number <= 1440
Conclusion
The Job History monitor report is a simple but very robust and adaptable quick T-SQL solution, using all the advantages of system job tables and SSRS. It is used for a general overview and quick pin pointing the causes and fixing problems resulting in automated job executions. The T-SQL query is quickly adaptable to any SQL Server system, one can even omit this report to only very critical daily jobs, weekly/monthly jobs, alter time intervals. Report results can be part of any scorecard or dashboard for your DBA or even management. At the same time, report can take advantages of report manager features such as zooming in/out, exporting to excel, PDF, sending as attachment in report subscription.
Author: Tomaz Kastrun (tomaz.kastrun@gmail.com)
Twitter: @tomaz_tsql