dbo.sysjobhistory (Transact-SQL)
Applies to:
SQL Server
Azure SQL Managed Instance
Contains information about the execution of scheduled jobs by the SQL Server Agent.
Note
In most cases the data is updated only after the job step completes and the table typically contains no records for job steps that are currently in progress, but in some cases underlying processes do provide information about in progress job steps.
This table is stored in the msdb
database.
Column name | Data type | Description |
---|---|---|
instance_id | int | Unique identifier for the row. |
job_id | uniqueidentifier | Job ID. |
step_id | int | ID of the step in the job. |
step_name | sysname | Name of the step. |
sql_message_id | int | ID of any SQL Server error message returned if the job failed. |
sql_severity | int | Severity of any SQL Server error. |
message | nvarchar(4000) | Text, if any, of a SQL Server error. |
run_status | int | Status of the job execution: 0 = Failed 1 = Succeeded 2 = Retry 3 = Canceled 4 = In Progress |
run_date | int | Date the job or step started execution, in YYYYMMDD format. For an In Progress history, this is the date/time the history was written. |
run_time | int | Time the job or step started in HHMMSS format. |
run_duration | int | Elapsed time in the execution of the job or step in HHMMSS format for time periods up to 24 hours. Find code to translate longer run durations in the example. |
operator_id_emailed | int | ID of the operator notified when the job completed. |
operator_id_netsent | int | ID of the operator notified by a message when the job completed. |
operator_id_paged | int | ID of the operator notified by pager when the job completed. |
retries_attempted | int | Number of retry attempts for the job or step. |
server | sysname | Name of the server where the job was executed. |
Example
The following Transact-SQL query converts the run_date
and run_time
columns into a single datetime column called LastRunDateTime
. The run_duration
column is also converted into a more user-friendly format. You can run the script in SQL Server Management Studio or Azure Data Studio.
SET NOCOUNT ON;
SELECT sj.name AS [Name],
sh.step_name AS [StepName],
DATETIMEFROMPARTS(
LEFT(padded_run_date, 4), -- year
SUBSTRING(padded_run_date, 5, 2), -- month
RIGHT(padded_run_date, 2), -- day
LEFT(padded_run_time, 2), -- hour
SUBSTRING(padded_run_time, 3, 2), -- minute
RIGHT(padded_run_time, 2), -- second
0) AS [LastRunDateTime], -- millisecond
CASE
WHEN sh.run_duration > 235959
THEN CAST((CAST(LEFT(CAST(sh.run_duration AS VARCHAR), LEN(CAST(sh.run_duration AS VARCHAR)) - 4) AS INT) / 24) AS VARCHAR) + '.' + RIGHT('00' + CAST(CAST(LEFT(CAST(sh.run_duration AS VARCHAR), LEN(CAST(sh.run_duration AS VARCHAR)) - 4) AS INT) % 24 AS VARCHAR), 2) + ':' + STUFF(CAST(RIGHT(CAST(sh.run_duration AS VARCHAR), 4) AS VARCHAR(6)), 3, 0, ':')
ELSE STUFF(STUFF(RIGHT(REPLICATE('0', 6) + CAST(sh.run_duration AS VARCHAR(6)), 6), 3, 0, ':'), 6, 0, ':')
END AS [LastRunDuration (d.HH:MM:SS)]
FROM msdb.dbo.sysjobs sj
INNER JOIN msdb.dbo.sysjobhistory sh
ON sj.job_id = sh.job_id
CROSS APPLY (
SELECT RIGHT('000000' + CAST(sh.run_time AS VARCHAR(6)), 6),
RIGHT('00000000' + CAST(sh.run_date AS VARCHAR(8)), 8)
) AS shp(padded_run_time, padded_run_date)
GO
Next steps
Learn more about related concepts in the following articles: