forked from soupowertuning/Script_SQLServer_Alerts
-
Notifications
You must be signed in to change notification settings - Fork 0
/
3.1 - CheckDB - Job and Alert.sql
164 lines (136 loc) · 5.14 KB
/
3.1 - CheckDB - Job and Alert.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
/***********************************************************************************************************************************
(C) 2016, autor: Fabricio França Lima
Blog: https://www.fabriciolima.net/blog/
Feedback: suporte@powertuning.com.br
Instagram: @fabriciofrancalima
Twitter: @fabriciodba
Facebook: https://www.facebook.com/fabricio.francalima
Linkedin: https://www.linkedin.com/in/fabriciofrancalima/
Consultoria: comercial@powertuning.com.br
***********************************************************************************************************************************/
USE Traces
GO
IF ( OBJECT_ID('[dbo].[stpCHECKDB_Databases]') IS NOT NULL )
DROP PROCEDURE [dbo].[stpCHECKDB_Databases]
GO
CREATE PROCEDURE [dbo].[stpCHECKDB_Databases]
AS
BEGIN
SET NOCOUNT ON
DECLARE @Databases TABLE (
[Id_Database] INT IDENTITY(1, 1),
[Nm_Database] VARCHAR(256)
)
DECLARE @Total INT, @Loop INT, @Nm_Database VARCHAR(256)
INSERT INTO @Databases( [Nm_Database] )
SELECT A.[name]
FROM [master].[sys].[databases] A
LEFT JOIN [dbo].Ignore_Databases B ON A.[name] = B.[Nm_Database]
WHERE A.[name] NOT IN ('tempdb')
AND A.[state_desc] = 'ONLINE'
and B.[Nm_Database] IS NULL
SELECT @Total = MAX([Id_Database])
FROM @Databases
SET @Loop = 1
WHILE ( @Loop <= @Total )
BEGIN
-- Se passar de 6 da manha deve terminar a execução automaticamente
IF(
( (SELECT DATEPART(WEEKDAY, GETDATE())) <> 1 AND (SELECT DATEPART(HOUR, GETDATE())) >= 6 ) -- SEGUNDA A SABADO - EXECUTA ATE AS 6 HORAS
OR ( (SELECT DATEPART(WEEKDAY, GETDATE())) = 1 AND (SELECT DATEPART(HOUR, GETDATE())) >= 23 ) -- DOMINGO - EXECUTA ATE AS 23 HORAS
)
BEGIN
BREAK
END
SELECT @Nm_Database = [Nm_Database]
FROM @Databases
WHERE [Id_Database] = @Loop
DBCC CHECKDB(@Nm_Database) WITH NO_INFOMSGS
SET @Loop = @Loop + 1
END
END
GO
USE [msdb]
GO
IF EXISTS (SELECT job_id FROM msdb.dbo.sysjobs_view WHERE name = N'DBA - Check Corruption Databases')
EXEC msdb.dbo.sp_delete_job @job_name=N'DBA - Check Corruption Databases', @delete_unused_schedule=1
GO
USE [msdb]
GO
BEGIN TRANSACTION
DECLARE @ReturnCode INT
SELECT @ReturnCode = 0
/****** Object: JobCategory [Database Maintenance] Script Date: 27/01/2017 14:49:04 ******/
IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'Database Maintenance' AND category_class=1)
BEGIN
EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'Database Maintenance'
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
END
DECLARE @jobId BINARY(16)
EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'DBA - Check Corruption Databases',
@enabled=0,
@notify_level_eventlog=0,
@notify_level_email=2,
@notify_level_netsend=0,
@notify_level_page=0,
@delete_level=0,
@description=N'No description available.',
@category_name=N'Database Maintenance',
@owner_login_name=N'sa',
@notify_email_operator_name=N'DBA_Operator',
@job_id = @jobId OUTPUT
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
/****** Object: Step [DBA - Check Corruption Databases] Script Date: 27/01/2017 14:49:04 ******/
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'DBA - Check Corruption Databases',
@step_id=1,
@cmdexec_success_code=0,
@on_success_action=1,
@on_success_step_id=0,
@on_fail_action=3,
@on_fail_step_id=0,
@retry_attempts=0,
@retry_interval=0,
@os_run_priority=0, @subsystem=N'TSQL',
@command=N'EXEC [dbo].[stpCHECKDB_Databases]',
@database_name=N'Traces',
@flags=0
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
/****** Object: Step [Alerta Corrupção Databases] Script Date: 27/01/2017 14:49:04 ******/
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Alert Database Corruption',
@step_id=2,
@cmdexec_success_code=0,
@on_success_action=2,
@on_success_step_id=0,
@on_fail_action=2,
@on_fail_step_id=0,
@retry_attempts=0,
@retry_interval=0,
@os_run_priority=0, @subsystem=N'TSQL',
@command=N'
EXEC stpRead_Error_log 0
EXEC [dbo].[stpAlert_CheckDB]',
@database_name=N'Traces',
@flags=0
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N'DBA - Check Corruption Databases',
@enabled=1,
@freq_type=4,
@freq_interval=1,
@freq_subday_type=1,
@freq_subday_interval=0,
@freq_relative_interval=0,
@freq_recurrence_factor=0,
@active_start_date=20170127,
@active_end_date=99991231,
@active_start_time=20000,
@active_end_time=235959
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)'
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
COMMIT TRANSACTION
GOTO EndSave
QuitWithRollback:
IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION
EndSave: