4_job_AdaptiveCycleErrorlog.sql 4.4 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124
  1. USE [msdb]
  2. GO
  3. IF EXISTS (SELECT job_id FROM msdb.dbo.sysjobs_view WHERE name = N'Daily Cycle Errorlog')
  4. EXEC msdb.dbo.sp_delete_job @job_name=N'Daily Cycle Errorlog', @delete_unused_schedule=1
  5. GO
  6. PRINT 'Creating Daily Cycle Log job';
  7. GO
  8. BEGIN TRANSACTION
  9. -- Set the Operator name to receive notifications, if any. Set the job owner, if not sa.
  10. DECLARE @customoper sysname, @jobowner sysname
  11. SET @customoper = 'SQLAdmins'
  12. SET @jobowner = 'sa'
  13. DECLARE @ReturnCode INT
  14. SELECT @ReturnCode = 0
  15. IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'Database Maintenance' AND category_class=1)
  16. BEGIN
  17. EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'Database Maintenance'
  18. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  19. END
  20. DECLARE @jobId BINARY(16)
  21. IF EXISTS (SELECT name FROM msdb.dbo.sysoperators WHERE name = @customoper)
  22. BEGIN
  23. EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'Daily Cycle Errorlog',
  24. @enabled=1,
  25. @notify_level_eventlog=2,
  26. @notify_level_email=2,
  27. @notify_level_netsend=2,
  28. @notify_level_page=2,
  29. @delete_level=0,
  30. @description=N'Cycles Errorlog when its size is over 20MB or its age over 15 days.',
  31. @category_name=N'Database Maintenance',
  32. @owner_login_name=@jobowner,
  33. @notify_email_operator_name=@customoper,
  34. @job_id = @jobId OUTPUT
  35. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  36. END
  37. ELSE
  38. BEGIN
  39. EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'Daily Cycle Errorlog',
  40. @enabled=1,
  41. @notify_level_eventlog=2,
  42. @notify_level_email=3,
  43. @notify_level_netsend=0,
  44. @notify_level_page=0,
  45. @delete_level=0,
  46. @description=N'Cycles Errorlog when its size is over 20MB or its age over 15 days.',
  47. @category_name=N'Database Maintenance',
  48. @owner_login_name=@jobowner,
  49. @job_id = @jobId OUTPUT
  50. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  51. END
  52. EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Adaptive Cycle Errorlog',
  53. @step_id=1,
  54. @cmdexec_success_code=0,
  55. @on_success_action=1,
  56. @on_success_step_id=0,
  57. @on_fail_action=2,
  58. @on_fail_step_id=0,
  59. @retry_attempts=0,
  60. @retry_interval=0,
  61. @os_run_priority=0, @subsystem=N'TSQL',
  62. @command=N'SET NOCOUNT ON;
  63. DECLARE @CycleMessage VARCHAR(255), @return_value int, @Output VARCHAR(32)
  64. DECLARE @ErrorLogs TABLE (ArchiveNumber tinyint, DateCreated DATETIME, LogFileSizeBytes int)
  65. INSERT into @ErrorLogs (ArchiveNumber, DateCreated, LogFileSizeBytes )
  66. EXEC master.dbo.sp_enumerrorlogs
  67. SELECT @CycleMessage = ''Current SQL Server ErrorLog was created on '' + CONVERT(VARCHAR, DateCreated , 105) + '' and is using '' +
  68. CASE WHEN LogFileSizeBytes BETWEEN 1024 AND 1048575 THEN CAST(LogFileSizeBytes/1024 AS VARCHAR(10)) + '' KB.''
  69. WHEN LogFileSizeBytes > 1048575 THEN CAST((LogFileSizeBytes/1024)/1024 AS VARCHAR(10)) + '' MB.''
  70. ELSE CAST(LogFileSizeBytes AS VARCHAR(4)) + '' Bytes.''
  71. END
  72. + CASE WHEN LogFileSizeBytes > 20971520 THEN '' The ErrorLog will be cycled because of its size.'' -- over 20MB
  73. WHEN DateCreated <= DATEADD(dd, -15,GETDATE()) THEN '' The ErrorLog will be cycled because of its age.'' -- over 15 days
  74. ELSE '' The ErrorLog will not be cycled.'' end
  75. FROM @ErrorLogs where ArchiveNumber = 1
  76. PRINT @CycleMessage
  77. IF @CycleMessage LIKE ''%will be cycled%''
  78. BEGIN
  79. EXEC @return_value = sp_cycle_errorlog
  80. SELECT @Output = CASE WHEN @return_value = 0 THEN ''ErrorLog was sucessfully cycled.'' ELSE ''Failure cycling Errorlog.'' END
  81. PRINT @Output
  82. END',
  83. @database_name=N'master',
  84. @flags=4
  85. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  86. EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1
  87. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  88. EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N'Daily Cycle Errorlog',
  89. @enabled=1,
  90. @freq_type=4,
  91. @freq_interval=1,
  92. @freq_subday_type=1,
  93. @freq_subday_interval=0,
  94. @freq_relative_interval=0,
  95. @freq_recurrence_factor=0,
  96. @active_start_date=20120529,
  97. @active_end_date=99991231,
  98. @active_start_time=235900,
  99. @active_end_time=235959
  100. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  101. EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)'
  102. IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
  103. COMMIT TRANSACTION
  104. GOTO EndSave
  105. QuitWithRollback:
  106. IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION
  107. EndSave:
  108. GO
  109. PRINT 'Daily Cycle Log job created';
  110. GO