Capture SQL Server Agent Job Last Execution Time

  • Hello.

    I am trying to solve in what I would have thought would be a more common problem. However, I am not seeing anyone online attempting to do this.

    Background-

    I have a powershell script that will query all of our servers in the enterprise to capture the SQL Server Agent Job History. What I want is to identify and eventually delete old, unused Agent Jobs that have been hanging around for a long time (10+ years in some cases).

    However, I am noticing that [msdb].dbo.SYSJOBHISTORY does not contain all the data that I see in the GUI for the last time the job Ran. For instance, If I check the GUI properties of some jobs, it displays a last execution time. My query Displays it as null even tho the GUI shows me the value. I am not sure if I am doing something wrong or if this is simply not possible to accurately capture this information. Below is my Query. Even when I just do a select * from [msdb].dbo.SYSJOBHISTORY - The Job does not show at all, when it does indeed have a time-stamp in the jobs properties.

    SELECT

    [sJOB].[name] AS [JobName]

    , [sDBP].[name] AS [JobOwner]

    , [sCAT].[name] AS [JobCategory]

    , [sJOB].[description] AS [JobDescription]

    , CASE [sJOB].[enabled]

    WHEN 1 THEN 'Yes'

    WHEN 0 THEN 'No'

    END AS [IsEnabled]

    , [sJOB].[date_created] AS [JobCreatedOn]

    , [sJOB].[date_modified] AS [JobLastModifiedOn]

    , MAX([msdb].DBO.AGENT_DATETIME(RUN_DATE, RUN_TIME)) AS [Last Time Job Ran On]

    , [sSVR].[name] AS [OriginatingServerName]

    , [sJSTP].[step_id] AS [JobStartStepNo]

    , [sJSTP].[step_name] AS [JobStartStepName]

    , CASE

    WHEN [sSCH].[schedule_uid] IS NULL THEN 'No'

    ELSE 'Yes'

    END AS [IsScheduled]

    , [sSCH].[name] AS [JobScheduleName]

    , CASE [sJOB].[delete_level]

    WHEN 0 THEN 'Never'

    WHEN 1 THEN 'On Success'

    WHEN 2 THEN 'On Failure'

    WHEN 3 THEN 'On Completion'

    END AS [JobDeletionCriterion]

    , [sSCH].[Schedule_ID]

    --INTO PB_SQLAgentJobInfo

    FROM

    [msdb].[dbo].[sysjobs] AS [sJOB]

    LEFT JOIN [msdb].[sys].[servers] AS [sSVR]

    ON [sJOB].[originating_server_id] = [sSVR].[server_id]

    LEFT JOIN [msdb].[dbo].[syscategories] AS [sCAT]

    ON [sJOB].[category_id] = [sCAT].[category_id]

    LEFT JOIN [msdb].[dbo].[sysjobsteps] AS [sJSTP]

    ON [sJOB].[job_id] = [sJSTP].[job_id]

    AND [sJOB].[start_step_id] = [sJSTP].[step_id]

    LEFT JOIN [msdb].[sys].[database_principals] AS [sDBP]

    ON [sJOB].[owner_sid] = [sDBP].[sid]

    LEFT JOIN [msdb].[dbo].[sysjobschedules] AS [sJOBSCH]

    ON [sJOB].[job_id] = [sJOBSCH].[job_id]

    LEFT JOIN [msdb].[dbo].[sysschedules] AS [sSCH]

    ON [sJOBSCH].[schedule_id] = [sSCH].[schedule_id]

    Left JOIN [msdb].dbo.SYSJOBHISTORY JH

    ON sJOB.job_id = JH.job_id

    Group By

    [sJOB].[name]

    , [sDBP].[name]

    , [sCAT].[name]

    , [sJOB].[description]

    , [sJOB].[enabled]

    , [sJOB].[date_created]

    , [sJOB].[date_modified]

    , [sSVR].[name]

    , [sJSTP].[step_id]

    , [sJSTP].[step_name]

    , [sSCH].[schedule_uid]

    , [sSCH].[name]

    , [sJOB].[delete_level]

    , [sSCH].[Schedule_ID]

    ORDER BY [JobName]

    Much Appreciated,

    Thanks!

  • I actually figured out how to do it by utilizing a CTE table to bring in msdb.dbo.sysjobacivity. Then inserting that into a memory table and joining back to that in the main query. If anyone else wants to do this feel free to help yourself!

    Declare @Temp as Table (Job_Name Varchar(400), LastRunDate DateTime2 )

    ;with raw(job_name, Run_DTM, rownum) as

    (

    select j.name, ja.start_execution_date as Run_DTM,row_number() over(partition by ja.job_id order by start_execution_date desc)

    from msdb.dbo.sysjobactivity ja inner join msdb.dbo.sysjobs j on j.job_id=ja.job_id

    )

    Insert Into @Temp

    select job_name, run_dtm as 'LastRunDate' from raw where rownum=1 order by Job_name

    SELECT [sSVR].[name] AS [OriginatingServerName]

    ,[JobName] = [jobs].[name]

    ,[Category] = [categories].[name]

    ,[Owner] = SUSER_SNAME([jobs].[owner_sid])

    ,[Enabled] = CASE [jobs].[enabled] WHEN 1 THEN 'Yes' ELSE 'No' END

    ,[Scheduled] = CASE [schedule].[enabled] WHEN 1 THEN 'Yes' ELSE 'No' END

    ,[Description] = [jobs].[description]

    , [JOBs].[date_created] AS [JobCreatedOn]

    , [JOBs].[date_modified] AS [JobLastModifiedOn]

    ,cte.LastRunDate As LastRunDate

    ,[Occurs] =

    CASE [schedule].[freq_type]

    WHEN 1 THEN 'Once'

    WHEN 4 THEN 'Daily'

    WHEN 8 THEN 'Weekly'

    WHEN 16 THEN 'Monthly'

    WHEN 32 THEN 'Monthly relative'

    WHEN 64 THEN 'When SQL Server Agent starts'

    WHEN 128 THEN 'Start whenever the CPU(s) become idle'

    ELSE ''

    END

    ,[Occurs_detail] =

    CASE [schedule].[freq_type]

    WHEN 1 THEN 'O'

    WHEN 4 THEN 'Every ' + CONVERT(VARCHAR, [schedule].[freq_interval]) + ' day(s)'

    WHEN 8 THEN 'Every ' + CONVERT(VARCHAR, [schedule].[freq_recurrence_factor]) + ' weeks(s) on ' +

    LEFT(

    CASE WHEN [schedule].[freq_interval] & 1 = 1 THEN 'Sunday, ' ELSE '' END +

    CASE WHEN [schedule].[freq_interval] & 2 = 2 THEN 'Monday, ' ELSE '' END +

    CASE WHEN [schedule].[freq_interval] & 4 = 4 THEN 'Tuesday, ' ELSE '' END +

    CASE WHEN [schedule].[freq_interval] & 8 = 8 THEN 'Wednesday, ' ELSE '' END +

    CASE WHEN [schedule].[freq_interval] & 16 = 16 THEN 'Thursday, ' ELSE '' END +

    CASE WHEN [schedule].[freq_interval] & 32 = 32 THEN 'Friday, ' ELSE '' END +

    CASE WHEN [schedule].[freq_interval] & 64 = 64 THEN 'Saturday, ' ELSE '' END ,

    LEN(

    CASE WHEN [schedule].[freq_interval] & 1 = 1 THEN 'Sunday, ' ELSE '' END +

    CASE WHEN [schedule].[freq_interval] & 2 = 2 THEN 'Monday, ' ELSE '' END +

    CASE WHEN [schedule].[freq_interval] & 4 = 4 THEN 'Tuesday, ' ELSE '' END +

    CASE WHEN [schedule].[freq_interval] & 8 = 8 THEN 'Wednesday, ' ELSE '' END +

    CASE WHEN [schedule].[freq_interval] & 16 = 16 THEN 'Thursday, ' ELSE '' END +

    CASE WHEN [schedule].[freq_interval] & 32 = 32 THEN 'Friday, ' ELSE '' END +

    CASE WHEN [schedule].[freq_interval] & 64 = 64 THEN 'Saturday, ' ELSE '' END

    ) - 1

    )

    WHEN 16 THEN 'Day ' + CONVERT(VARCHAR, [schedule].[freq_interval]) + ' of every ' + CONVERT(VARCHAR, [schedule].[freq_recurrence_factor]) + ' month(s)'

    WHEN 32 THEN 'The ' +

    CASE [schedule].[freq_relative_interval]

    WHEN 1 THEN 'First'

    WHEN 2 THEN 'Second'

    WHEN 4 THEN 'Third'

    WHEN 8 THEN 'Fourth'

    WHEN 16 THEN 'Last'

    END +

    CASE [schedule].[freq_interval]

    WHEN 1 THEN ' Sunday'

    WHEN 2 THEN ' Monday'

    WHEN 3 THEN ' Tuesday'

    WHEN 4 THEN ' Wednesday'

    WHEN 5 THEN ' Thursday'

    WHEN 6 THEN ' Friday'

    WHEN 7 THEN ' Saturday'

    WHEN 8 THEN ' Day'

    WHEN 9 THEN ' Weekday'

    WHEN 10 THEN ' Weekend Day'

    END + ' of every ' + CONVERT(VARCHAR, [schedule].[freq_recurrence_factor]) + ' month(s)'

    ELSE ''

    END

    ,[Frequency] =

    CASE [schedule].[freq_subday_type]

    WHEN 1 THEN 'Occurs once at ' +

    STUFF(STUFF(RIGHT('000000' + CONVERT(VARCHAR(8), [schedule].[active_start_time]), 6), 5, 0, ':'), 3, 0, ':')

    WHEN 2 THEN 'Occurs every ' +

    CONVERT(VARCHAR, [schedule].[freq_subday_interval]) + ' Seconds(s) between ' +

    STUFF(STUFF(RIGHT('000000' + CONVERT(VARCHAR(8), [schedule].[active_start_time]), 6), 5, 0, ':'), 3, 0, ':') + ' and ' +

    STUFF(STUFF(RIGHT('000000' + CONVERT(VARCHAR(8), [schedule].[active_end_time]), 6), 5, 0, ':'), 3, 0, ':')

    WHEN 4 THEN 'Occurs every ' +

    CONVERT(VARCHAR, [schedule].[freq_subday_interval]) + ' Minute(s) between ' +

    STUFF(STUFF(RIGHT('000000' + CONVERT(VARCHAR(8), [schedule].[active_start_time]), 6), 5, 0, ':'), 3, 0, ':') + ' and ' +

    STUFF(STUFF(RIGHT('000000' + CONVERT(VARCHAR(8), [schedule].[active_end_time]), 6), 5, 0, ':'), 3, 0, ':')

    WHEN 8 THEN 'Occurs every ' +

    CONVERT(VARCHAR, [schedule].[freq_subday_interval]) + ' Hour(s) between ' +

    STUFF(STUFF(RIGHT('000000' + CONVERT(VARCHAR(8), [schedule].[active_start_time]), 6), 5, 0, ':'), 3, 0, ':') + ' and ' +

    STUFF(STUFF(RIGHT('000000' + CONVERT(VARCHAR(8), [schedule].[active_end_time]), 6), 5, 0, ':'), 3, 0, ':')

    ELSE ''

    END

    ,[AvgDurationInSec] = CONVERT(DECIMAL(10, 2), [jobhistory].[AvgDuration])

    ,[Next_Run_Date] =

    CASE [jobschedule].[next_run_date]

    WHEN 0 THEN CONVERT(DATETIME, '1900/1/1')

    ELSE CONVERT(DATETIME, CONVERT(CHAR(8), [jobschedule].[next_run_date], 112) + ' ' +

    STUFF(STUFF(RIGHT('000000' + CONVERT(VARCHAR(8), [jobschedule].[next_run_time]), 6), 5, 0, ':'), 3, 0, ':'))

    END

    FROM [msdb].[dbo].[sysjobs] AS [jobs] WITh(NOLOCK)

    LEFT OUTER JOIN [msdb].[dbo].[sysjobschedules] AS [jobschedule] WITh(NOLOCK)

    ON [jobs].[job_id] = [jobschedule].[job_id]

    LEFT OUTER JOIN [msdb].[dbo].[sysschedules] AS [schedule] WITh(NOLOCK)

    ON [jobschedule].[schedule_id] = [schedule].[schedule_id]

    INNER JOIN [msdb].[dbo].[syscategories] [categories] WITh(NOLOCK)

    ON [jobs].[category_id] = [categories].[category_id]

    LEFT OUTER JOIN

    (SELECT [job_id], [AvgDuration] = (SUM((([run_duration] / 10000 * 3600) +

    (([run_duration] % 10000) / 100 * 60) +

    ([run_duration] % 10000) % 100)) * 1.0) / COUNT([job_id])

    FROM [msdb].[dbo].[sysjobhistory] WITh(NOLOCK)

    WHERE [step_id] = 0

    GROUP BY [job_id]

    ) AS [jobhistory]

    ON [jobhistory].[job_id] = [jobs].[job_id]

    Inner Join @Temp cte on cte.job_name = jobs.name

    LEFT JOIN [msdb].[sys].[servers] AS [sSVR]

    ON [JOBs].[originating_server_id] = [sSVR].[server_id]

  • If you are truncating job history, you may have a lot of jobs you can't get rid of because it shows no history.

    In which case you'll want to search for jobs that have never been executed. But then you'll have to figure out how to tell the difference between new jobs that haven't been executed yet and old jobs that have no history for them. Fun, yeah?

    Brandie Tarvin, MCITP Database AdministratorLiveJournal Blog: http://brandietarvin.livejournal.com/[/url]On LinkedIn!, Google+, and Twitter.Freelance Writer: ShadowrunLatchkeys: Nevermore, Latchkeys: The Bootleg War, and Latchkeys: Roscoes in the Night are now available on Nook and Kindle.

Viewing 3 posts - 1 through 2 (of 2 total)

You must be logged in to reply to this topic. Login to reply