|
31 | 31 | 29-Apr-2019 - Add logic to send Blocking info to Slack Email |
32 | 32 | 13-May-2019 - Modify the Blocking Mail Query with procedure DBA.dbo.usp_WhoIsActive_Blocking |
33 | 33 | 20-Jun-2019 - @p_PerformAutoExecutionOfLogWalkJob - Add logic to run Log Walk Job if last execution was a failure due to blocking issue, and there are no Blockers |
| 34 | + 27-Jul-2019 - Adding JobSchedule & NextRunTime in Mailer Output |
34 | 35 | */ |
35 | 36 | SET NOCOUNT ON; |
36 | 37 |
|
|
51 | 52 | DECLARE @IsBlockingIssue BIT; |
52 | 53 | DECLARE @AreInDirectConnections BIT; |
53 | 54 | DECLARE @_SendMailRequired BIT; |
| 55 | + DECLARE @JobSchedule varchar(255), |
| 56 | + @NextRunTime datetime; |
54 | 57 | DECLARE @_mailSubject VARCHAR(255) |
55 | 58 | ,@_mailBody VARCHAR(4000); |
56 | 59 | IF OBJECT_ID('DBA..LogWalkThresholdInstance') IS NULL |
@@ -273,6 +276,90 @@ BEGIN |
273 | 276 | IF @p_Verbose = 1 |
274 | 277 | SELECT [@_collection_time_start] = @_collection_time_start, [@_collection_time_end] = @_collection_time_end; |
275 | 278 |
|
| 279 | + -- Find job schedule & NextRunTime |
| 280 | + ;WITH T_Schedules AS |
| 281 | + ( |
| 282 | + select S.name AS JobName, |
| 283 | + SS.name AS ScheduleName, |
| 284 | + CASE(SS.freq_type) |
| 285 | + WHEN 1 THEN 'Once' |
| 286 | + WHEN 4 THEN 'Daily' |
| 287 | + WHEN 8 THEN (case when (SS.freq_recurrence_factor > 1) then 'Every ' + convert(varchar(3),SS.freq_recurrence_factor) + ' Weeks' else 'Weekly' end) |
| 288 | + WHEN 16 THEN (case when (SS.freq_recurrence_factor > 1) then 'Every ' + convert(varchar(3),SS.freq_recurrence_factor) + ' Months' else 'Monthly' end) |
| 289 | + WHEN 32 THEN 'Every ' + convert(varchar(3),SS.freq_recurrence_factor) + ' Months' -- RELATIVE |
| 290 | + WHEN 64 THEN 'SQL Startup' |
| 291 | + WHEN 128 THEN 'SQL Idle' |
| 292 | + ELSE '??' |
| 293 | + END AS Frequency, |
| 294 | + CASE |
| 295 | + WHEN (freq_type = 1) then 'One time only' |
| 296 | + WHEN (freq_type = 4 and freq_interval = 1) then 'Every Day' |
| 297 | + WHEN (freq_type = 4 and freq_interval > 1) then 'Every ' + convert(varchar(10),freq_interval) + ' Days' |
| 298 | + WHEN (freq_type = 8) then (select 'Weekly Schedule' = MIN(D1+ D2+D3+D4+D5+D6+D7 ) |
| 299 | + from (select SS.schedule_id, |
| 300 | + freq_interval, |
| 301 | + 'D1' = CASE WHEN (freq_interval & 1 <> 0) then 'Sun ' ELSE '' END, |
| 302 | + 'D2' = CASE WHEN (freq_interval & 2 <> 0) then 'Mon ' ELSE '' END, |
| 303 | + 'D3' = CASE WHEN (freq_interval & 4 <> 0) then 'Tue ' ELSE '' END, |
| 304 | + 'D4' = CASE WHEN (freq_interval & 8 <> 0) then 'Wed ' ELSE '' END, |
| 305 | + 'D5' = CASE WHEN (freq_interval & 16 <> 0) then 'Thu ' ELSE '' END, |
| 306 | + 'D6' = CASE WHEN (freq_interval & 32 <> 0) then 'Fri ' ELSE '' END, |
| 307 | + 'D7' = CASE WHEN (freq_interval & 64 <> 0) then 'Sat ' ELSE '' END |
| 308 | + from msdb..sysschedules ss |
| 309 | + where freq_type = 8 |
| 310 | + ) as F |
| 311 | + where schedule_id = SJ.schedule_id |
| 312 | + ) |
| 313 | + WHEN (freq_type = 16) then 'Day ' + convert(varchar(2),freq_interval) |
| 314 | + WHEN (freq_type = 32) then (select freq_rel + WDAY |
| 315 | + from (select SS.schedule_id, |
| 316 | + 'freq_rel' = CASE(freq_relative_interval) |
| 317 | + WHEN 1 then 'First' |
| 318 | + WHEN 2 then 'Second' |
| 319 | + WHEN 4 then 'Third' |
| 320 | + WHEN 8 then 'Fourth' |
| 321 | + WHEN 16 then 'Last' |
| 322 | + ELSE '??' |
| 323 | + END, |
| 324 | + 'WDAY' = CASE (freq_interval) |
| 325 | + WHEN 1 then ' Sun' |
| 326 | + WHEN 2 then ' Mon' |
| 327 | + WHEN 3 then ' Tue' |
| 328 | + WHEN 4 then ' Wed' |
| 329 | + WHEN 5 then ' Thu' |
| 330 | + WHEN 6 then ' Fri' |
| 331 | + WHEN 7 then ' Sat' |
| 332 | + WHEN 8 then ' Day' |
| 333 | + WHEN 9 then ' Weekday' |
| 334 | + WHEN 10 then ' Weekend' |
| 335 | + ELSE '??' |
| 336 | + END |
| 337 | + from msdb..sysschedules SS |
| 338 | + where SS.freq_type = 32 |
| 339 | + ) as WS |
| 340 | + where WS.schedule_id = SS.schedule_id |
| 341 | + ) |
| 342 | + END AS Interval, |
| 343 | + CASE (freq_subday_type) |
| 344 | + WHEN 1 then left(stuff((stuff((replicate('0', 6 - len(active_start_time)))+ convert(varchar(6),active_start_time),3,0,':')),6,0,':'),8) |
| 345 | + WHEN 2 then 'Every ' + convert(varchar(10),freq_subday_interval) + ' seconds' |
| 346 | + WHEN 4 then 'Every ' + convert(varchar(10),freq_subday_interval) + ' minutes' |
| 347 | + WHEN 8 then 'Every ' + convert(varchar(10),freq_subday_interval) + ' hours' |
| 348 | + ELSE '??' |
| 349 | + END AS [Time], |
| 350 | + CASE SJ.next_run_date |
| 351 | + WHEN 0 THEN cast('n/a' as char(10)) |
| 352 | + ELSE convert(char(10), convert(datetime, convert(char(8),SJ.next_run_date)),120) + ' ' + left(stuff((stuff((replicate('0', 6 - len(next_run_time)))+ convert(varchar(6),next_run_time),3,0,':')),6,0,':'),8) |
| 353 | + END AS NextRunTime |
| 354 | + from msdb.dbo.sysjobs S |
| 355 | + left join msdb.dbo.sysjobschedules SJ on S.job_id = SJ.job_id |
| 356 | + left join msdb.dbo.sysschedules SS on SS.schedule_id = SJ.schedule_id |
| 357 | + where s.name = @p_JobName |
| 358 | + ) |
| 359 | + SELECT @JobSchedule = Frequency + ' (' + Interval + ') - ' + [Time] |
| 360 | + ,@NextRunTime = NextRunTime |
| 361 | + FROM T_Schedules; |
| 362 | + |
276 | 363 | -- Find Job Session along with its Blockers |
277 | 364 | IF OBJECT_ID('tempdb..#JobSessionBlockers') IS NOT NULL |
278 | 365 | DROP TABLE #JobSessionBlockers; |
@@ -441,6 +528,8 @@ SQL Agent Job '+QUOTENAME(@p_JobName)+' has been failing for '+cast(@NoOfContino |
441 | 528 | LAST JOB RUN: '+CAST(jh.RunDateTime AS varchar(50))+' |
442 | 529 | DURATION: '+CAST(jh.RunDurationMinutes AS varchar(10))+' Minutes |
443 | 530 | STATUS: Failed |
| 531 | +SCHEDULE: '+ISNULL(@JobSchedule,'')+' |
| 532 | +NextRunTime: '+ISNULL(CAST(@NextRunTime AS VARCHAR(40)),'')+' |
444 | 533 | MESSAGES: Job '+QUOTENAME(@p_JobName)+' COULD NOT obtain EXCLUSIVE access of underlying database to start its activity. |
445 | 534 | RCA: Kindly execute below query to find out details of Blockers. |
446 | 535 |
|
@@ -541,6 +630,8 @@ SQL Agent Job '+QUOTENAME(@p_JobName)+' has been failing for '+cast(@NoOfContino |
541 | 630 | LAST JOB RUN: '+CAST(jh.RunDateTime AS varchar(50))+' |
542 | 631 | DURATION: '+CAST(jh.RunDurationMinutes AS varchar(10))+' Minutes |
543 | 632 | STATUS: Failed |
| 633 | +SCHEDULE: '+ISNULL(@JobSchedule,'')+' |
| 634 | +NextRunTime: '+ISNULL(CAST(@NextRunTime AS VARCHAR(40)),'')+' |
544 | 635 |
|
545 | 636 | Kindly check Job Step Error Message' |
546 | 637 | FROM @T_JobHistory as jh |
|
0 commit comments