Agent job schedules - next run date - how it gets updated?

  • Hi All,

    I want to understand the behavior of a scheduled job. Here is the scenario: I have a slow running job.

    Now, assuming the job is scheduled for every day every 5 mins but the job is still running over 30 mins due to blocking, what happens every time when it hits its schedule i.e every 5 mins? Since the job is still running , it ignores the next schedule and keep running? or throws any error message ? what happens internally?

    Secondly, does sql server updates the next run date every 5 mins or ignores and keeps on running? how does [next_run_date] in [msdb].[dbo].[sysjobschedules] gets updated? I mean what is the logic behind updating this column.

    The reason, why I am asking this is, I have created 2 sql agent jobs and kept it run in a loop. Again, this is only for testing purpose and that to on my local sql instance. So, while the jobs are running (i.e. they are running almost over 30 mins), then I went to properties of each job and re-scheduled the jobs to run every 5 mins. After doing so, and when I check the job schedule next run date , it shows wrong value. That's why I want to understand how this next run date value gets updated

    Using below query to retrieve the job schedules

    SELECT [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]

    ,[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]

    Appreciate your help.

    Thank you.

  • It gets updated every 20 minutes.

  • How to find that every 20 mins it gets updated? any query ?

    My SQL Version is :Microsoft SQL Server 2008 (SP3) - 10.0.5500.0 (X64) Developer Edition (64-bit)

  • MSDN details its a 20 minute refresh

    https://msdn.microsoft.com/en-gb/library/ms188924(v=sql.105).aspx

  • Interesting that the table updates every 20 minutes but you can schedule jobs to run every second.

    If the job is scheduled to run every 5 minutes but is still running after 20 minutes, one of two things should occur. One, if the job is still active at the next time it is to run it should not be fired. Two, if it is fired you should get an error indicating that the job is already active. The second is what happens when you attempt to manually start a job that is currently active. If I remember correctly, the first is what occurs when a schedule is used to run the job.

  • Based on personal observations, I believe the schedule also gets update at the completion of every job run.



    Alvin Ramard
    Memphis PASS Chapter[/url]

    All my SSC forum answers come with a money back guarantee. If you didn't like the answer then I'll gladly refund what you paid for it.

    For best practices on asking questions, please read the following article: Forum Etiquette: How to post data/code on a forum to get the best help[/url]

  • Thank you all. Valuable info.

Viewing 7 posts - 1 through 6 (of 6 total)

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