Skip to content

Commit 6a15e13

Browse files
committed
initial
0 parents  commit 6a15e13

File tree

123 files changed

+9431
-0
lines changed

Some content is hidden

Large Commits have some content hidden by default. Use the searchbox below for content that may be hidden.

123 files changed

+9431
-0
lines changed

ALLOW_PAGE_LOCKS.sql

+8
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,8 @@
1+
select 'alter INDEX [' + i.name + '] ON [' + s.name + '].[' + o.name + '] SET (ALLOW_PAGE_LOCKS = ON) --this is default'
2+
, * from sys.indexes i
3+
inner join sys.objects o on i.object_id = o.object_id
4+
inner join sys.schemas s on s.schema_id = o.schema_id
5+
where allow_page_locks = 0
6+
and o.is_ms_shipped = 0
7+
8+
+140
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,140 @@
1+
--TODO: Change the operator name [email protected]
2+
--TODO: Uncomment --EXEC (@TSQL) when confirmed
3+
4+
USE [msdb]
5+
GO
6+
7+
--These jobs do not have a notify operator setting
8+
select j.job_id, j.name, CategoryName = jc.name, j.enabled, j.description
9+
, OwnerName = suser_sname(j.owner_sid), date_created,date_modified, j.notify_email_operator_id
10+
from msdb.dbo.sysjobs j
11+
inner join msdb.dbo.syscategories jc
12+
on j.category_id = jc.category_id
13+
where j.notify_email_operator_id = 0
14+
and j.name not in ('syspolicy_purge_history')
15+
16+
DECLARE AddFailureNotifications CURSOR FAST_FORWARD
17+
FOR
18+
select convert(nvarchar(4000), '
19+
EXEC msdb.dbo.sp_update_job @job_id=N'''+convert(varchar(64), job_id)+''', /*'+j.name+'*/
20+
@notify_level_email=2,
21+
@notify_email_operator_name=N''[email protected]''')
22+
from msdb.dbo.sysjobs j
23+
where j.notify_email_operator_id = 0
24+
and j.name not in ('syspolicy_purge_history')
25+
26+
declare @tsql nvarchar(4000) = null
27+
OPEN AddFailureNotifications
28+
FETCH NEXT FROM AddFailureNotifications
29+
INTO @tsql
30+
31+
WHILE @@FETCH_STATUS = 0
32+
BEGIN
33+
EXEC (@TSQL)
34+
SELECT @TSQL
35+
FETCH NEXT FROM AddFailureNotifications
36+
INTO @tsql
37+
END
38+
39+
CLOSE AddFailureNotifications
40+
DEALLOCATE AddFailureNotifications;
41+
42+
/*
43+
44+
45+
--Change the operator name [email protected]
46+
--you may need to change the @server_name value below
47+
48+
USE [msdb]
49+
GO
50+
51+
BEGIN TRANSACTION
52+
DECLARE @ReturnCode INT
53+
SELECT @ReturnCode = 0
54+
55+
IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'[Uncategorized (Local)]' AND category_class=1)
56+
BEGIN
57+
EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'[Uncategorized (Local)]'
58+
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
59+
60+
END
61+
62+
DECLARE @jobId BINARY(16)
63+
EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'Add Failure Notifications',
64+
@enabled=1,
65+
@notify_level_eventlog=2,
66+
@notify_level_email=2,
67+
@notify_level_netsend=0,
68+
@notify_level_page=0,
69+
@delete_level=0,
70+
@description=N'Adds failure notification emails to any jobs that are created',
71+
@category_name=N'[Uncategorized (Local)]',
72+
@owner_login_name=N'sa',
73+
@notify_email_operator_name=N'[email protected]', @job_id = @jobId OUTPUT
74+
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
75+
76+
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'tsql',
77+
@step_id=1,
78+
@cmdexec_success_code=0,
79+
@on_success_action=1,
80+
@on_success_step_id=0,
81+
@on_fail_action=2,
82+
@on_fail_step_id=0,
83+
@retry_attempts=0,
84+
@retry_interval=0,
85+
@os_run_priority=0, @subsystem=N'TSQL',
86+
@command=N'USE [msdb]
87+
GO
88+
89+
DECLARE AddFailureNotifications CURSOR FAST_FORWARD
90+
FOR
91+
select convert(nvarchar(4000), ''
92+
EXEC msdb.dbo.sp_update_job @job_id=N''''''+convert(varchar(64), job_id)+'''''',
93+
@notify_level_email=2,
94+
@notify_level_netsend=2,
95+
@notify_level_page=2,
96+
@notify_email_operator_name=N''''[email protected]'''''')
97+
from msdb.dbo.sysjobs
98+
where notify_email_operator_id = 0
99+
100+
declare @tsql nvarchar(4000) = null
101+
OPEN AddFailureNotifications
102+
FETCH NEXT FROM AddFailureNotifications
103+
INTO @tsql
104+
105+
WHILE @@FETCH_STATUS = 0
106+
BEGIN
107+
EXEC (@TSQL)
108+
FETCH NEXT FROM AddFailureNotifications
109+
INTO @tsql
110+
END',
111+
@database_name=N'msdb',
112+
@flags=4
113+
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
114+
EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1
115+
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
116+
EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N'nightly',
117+
@enabled=1,
118+
@freq_type=4,
119+
@freq_interval=1,
120+
@freq_subday_type=1,
121+
@freq_subday_interval=0,
122+
@freq_relative_interval=0,
123+
@freq_recurrence_factor=0,
124+
@active_start_date=20150216,
125+
@active_end_date=99991231,
126+
@active_start_time=200000,
127+
@active_end_time=235959,
128+
@schedule_uid=N'fd1a2b03-1e0b-487d-ac6f-9eac60fc4f6a'
129+
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
130+
EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)'
131+
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
132+
COMMIT TRANSACTION
133+
GOTO EndSave
134+
QuitWithRollback:
135+
IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION
136+
EndSave:
137+
138+
GO
139+
140+
*/
+39
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,39 @@
1+
--TODO: Change the operator name [email protected]
2+
--TODO: Uncomment --EXEC (@TSQL) when confirmed
3+
4+
5+
--These jobs do not have a notify operator setting
6+
select j.job_id, j.name, CategoryName = jc.name, j.enabled, j.description
7+
, OwnerName = suser_sname(j.owner_sid), date_created,date_modified, j.notify_email_operator_id
8+
from msdb.dbo.sysjobs j
9+
inner join msdb.dbo.syscategories jc
10+
on j.category_id = jc.category_id
11+
where j.notify_email_operator_id = 0
12+
and j.name not in ('syspolicy_purge_history')
13+
14+
DECLARE AddFailureNotifications CURSOR FAST_FORWARD
15+
FOR
16+
select convert(nvarchar(4000), '
17+
EXEC msdb.dbo.sp_update_job @job_id=N'''+convert(varchar(64), job_id)+''', /*'+j.name+'*/
18+
@notify_level_email=2,
19+
@notify_email_operator_name=N''[email protected]''')
20+
from msdb.dbo.sysjobs j
21+
where j.notify_email_operator_id = 0
22+
and j.name not in ('syspolicy_purge_history')
23+
24+
declare @tsql nvarchar(4000) = null
25+
OPEN AddFailureNotifications
26+
FETCH NEXT FROM AddFailureNotifications
27+
INTO @tsql
28+
29+
WHILE @@FETCH_STATUS = 0
30+
BEGIN
31+
--EXEC (@TSQL)
32+
SELECT @TSQL
33+
FETCH NEXT FROM AddFailureNotifications
34+
INTO @tsql
35+
END
36+
37+
CLOSE AddFailureNotifications
38+
DEALLOCATE AddFailureNotifications;
39+

Availability Groups/AG owner.sql

+18
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,18 @@
1+
--should not be owned by named account!
2+
3+
SELECT ar.replica_server_name
4+
,ag.name AS ag_name
5+
,ar.owner_sid
6+
,sp.name
7+
FROM sys.availability_replicas ar
8+
LEFT JOIN sys.server_principals sp
9+
ON sp.sid = ar.owner_sid
10+
INNER JOIN sys.availability_groups ag
11+
ON ag.group_id = ar.group_id
12+
WHERE ar.replica_server_name = SERVERPROPERTY('ServerName') ;
13+
14+
/*
15+
16+
ALTER AUTHORIZATION ON AVAILABILITY GROUP::[drAG1] to [sa] ;
17+
18+
*/

Availability Groups/AG_Monitor.sql

+77
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,77 @@
1+
--On a secondary replica, this view returns a row for every secondary database on the server instance.
2+
--On the primary replica, this view returns a row for each primary database and an additional row for the corresponding secondary database.
3+
4+
--Updated WDA 20170622
5+
6+
IF NOT EXISTS (
7+
SELECT @@SERVERNAME, *
8+
FROM sys.dm_hadr_availability_replica_states rs
9+
inner join sys.availability_databases_cluster dc
10+
on rs.group_id = dc.group_id
11+
WHERE is_local = 1
12+
and role_desc = 'PRIMARY'
13+
)
14+
SELECT 'Recommend: Run This Script on Primary Replica';
15+
16+
17+
declare @start_tick bigint, @start_cntr bigint
18+
19+
select @start_tick = MAX(ms_ticks), @start_cntr = MAX(cntr_value) --the availability database with the highest Tdata_loss becomes the limiting value for RPO compliance.
20+
from sys.dm_os_sys_info
21+
cross apply sys.dm_os_performance_counters where counter_name like 'Log Bytes Flushed/sec%'
22+
23+
waitfor delay '00:00:02'
24+
25+
declare @end_tick bigint, @end_cntr bigint
26+
select @end_tick = MAX(ms_ticks), @end_cntr = MAX(cntr_value) --the availability database with the highest Tdata_loss becomes the limiting value for RPO compliance.
27+
from sys.dm_os_sys_info
28+
cross apply sys.dm_os_performance_counters where counter_name like 'Log Bytes Flushed/sec%'
29+
30+
declare @LogBytesFushed decimal(19,2)
31+
set @LogBytesFushed = (@end_cntr - @start_cntr) / NULLIF(@end_tick - @start_tick,0)
32+
33+
select
34+
Replica = ar.replica_server_name + ' ' + case when is_local = 1 then '(local)' else '' end
35+
, Replica_Role = case when last_received_time is null then 'PRIMARY' ELSE 'SECONDARY ('+ar.secondary_role_allow_connections_desc+')' END
36+
, DB = db_name(database_id)
37+
, dm.synchronization_state_desc
38+
, dm.synchronization_health_desc
39+
, ar.availability_mode_desc
40+
, ar.failover_mode_desc
41+
, Suspended = case is_suspended when 1 then suspend_reason_desc else null end
42+
, last_received_time
43+
, last_commit_time
44+
, redo_queue_size_mb = redo_queue_size/1024.
45+
, Redo_Time_Left_s_RTO = dm.redo_queue_size/NULLIF(dm.redo_rate,0) --https://msdn.microsoft.com/en-us/library/dn135338(v=sql.110).aspx --only part of RTO
46+
, Log_Send_Queue_RPO = dm.log_send_queue_size/NULLIF(@LogBytesFushed ,0) --Rate
47+
, ar.backup_priority
48+
, ar.modify_date
49+
, ar.endpoint_url
50+
, ar.read_only_routing_url
51+
from sys.dm_hadr_database_replica_states dm
52+
INNER JOIN sys.availability_replicas ar on dm.replica_id = ar.replica_id and dm.group_id = ar.group_id
53+
ORDER BY DB, [Replica], Replica_Role
54+
--WHERE db_name(database_id) = 'operations'
55+
56+
--SELECT log_reuse_wait_desc FROM sys.databases WHERE name = 'operations'
57+
58+
--Check for suspect pages (hopefully 0 rows returned)
59+
--https://msdn.microsoft.com/en-us/library/ms191301.aspx
60+
SELECT * FROM msdb.dbo.suspect_pages
61+
WHERE (event_type <= 3);
62+
63+
--Check for autorepair events (hopefully 0 rows returned)
64+
--https://msdn.microsoft.com/en-us/library/bb677167.aspx
65+
select db = db_name(database_id)
66+
, file_id
67+
, page_id
68+
, error_type
69+
, page_status
70+
, modification_time
71+
from sys.dm_hadr_auto_page_repair order by modification_time desc
72+
73+
74+
--https://msdn.microsoft.com/en-us/library/ff877972(v=sql.110).aspx
75+
--https://msdn.microsoft.com/en-us/library/dn135338(v=sql.110).aspx
76+
--https://blogs.msdn.microsoft.com/psssql/2013/09/23/interpreting-the-counter-values-from-sys-dm_os_performance_counters/
77+
--https://msdn.microsoft.com/en-us/library/ms175048.aspx
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,89 @@
1+
declare @tempperfmon table (
2+
[object_name] nchar (256) null,
3+
counter_name nchar (256) null,
4+
instance_name nchar (256) null,
5+
cntr_value bigint null
6+
, second_value bigint null
7+
)
8+
9+
--For databases both the primary and secondary, with send/receive counters reflecting the local replica
10+
insert into @tempperfmon ([object_name],counter_name,instance_name,cntr_value)
11+
select [object_name],counter_name,instance_name,cntr_value
12+
from sys.dm_os_performance_counters
13+
where [object_name] like '%Availability Replica%' and instance_name <> '_Total' and
14+
( counter_name = 'Bytes Received from Replica/sec' --From the availability replica. Pings and status updates will generate network traffic even on databases with no user updates.
15+
or counter_name = 'Bytes Sent to Replica/sec' --Sent to the remote replica. On primary, sent to the secondary replica. On secondary, sent to the primary replica.
16+
or counter_name = 'Bytes Sent to Transport/sec' --Sent over the network to the remote replica. On primary, sent to the secondary replica. On secondary, sent to the primary replica.
17+
or counter_name = 'Flow Control Time (ms/sec)' --Time in milliseconds that log stream messages waited for send flow control, in the last second.
18+
or counter_name = 'Receives from Replica/Sec'
19+
or counter_name = 'Sends to Replica/Sec'
20+
21+
)
22+
23+
insert into @tempperfmon ([object_name],counter_name,instance_name,cntr_value)
24+
--Only valid for databases in the secondary replica role
25+
select [object_name],counter_name,instance_name,cntr_value
26+
from sys.dm_os_performance_counters
27+
where [object_name] like '%database replica%' and instance_name <> '_Total' and
28+
( counter_name = 'File Bytes Received/sec' --FILESTREAM data only
29+
or counter_name = 'Log Bytes Received/sec' --Amount of log records received by the secondary replica for the database in the last second.'
30+
or counter_name = 'Log remaining for undo' --The amount of log in kilobytes remaining to complete the undo phase.
31+
)
32+
33+
WAITFOR DELAY '00:00:05'; --5s
34+
35+
36+
--For databases both the primary and secondary, with send/receive counters reflecting the local replica
37+
insert into @tempperfmon ([object_name],counter_name,instance_name,second_value)
38+
select [object_name],counter_name,instance_name,cntr_value
39+
from sys.dm_os_performance_counters
40+
where [object_name] like '%Availability Replica%' and instance_name <> '_Total' and
41+
( counter_name = 'Bytes Received from Replica/sec' --From the availability replica. Pings and status updates will generate network traffic even on databases with no user updates.
42+
or counter_name = 'Bytes Sent to Replica/sec' --Sent to the remote replica. On primary, sent to the secondary replica. On secondary, sent to the primary replica.
43+
or counter_name = 'Bytes Sent to Transport/sec' --Sent over the network to the remote replica. On primary, sent to the secondary replica. On secondary, sent to the primary replica.
44+
or counter_name = 'Flow Control Time (ms/sec)' --Time in milliseconds that log stream messages waited for send flow control, in the last second.
45+
or counter_name = 'Receives from Replica/Sec'
46+
or counter_name = 'Sends to Replica/Sec'
47+
48+
)
49+
50+
insert into @tempperfmon ([object_name],counter_name,instance_name,second_value)
51+
--Only valid for databases in the secondary replica role
52+
select [object_name],counter_name,instance_name,cntr_value
53+
from sys.dm_os_performance_counters
54+
where [object_name] like '%database replica%' and instance_name <> '_Total' and
55+
( counter_name = 'File Bytes Received/sec' --FILESTREAM data only
56+
or counter_name = 'Log Bytes Received/sec' --Amount of log records received by the secondary replica for the database in the last second.'
57+
or counter_name = 'Log remaining for undo' --The amount of log in kilobytes remaining to complete the undo phase.
58+
)
59+
60+
select
61+
[object_name],counter_name,instance_name
62+
, Observation = (max(second_value) - max(cntr_value)) /5.
63+
from @tempperfmon
64+
group by [object_name],counter_name,instance_name
65+
66+
/*
67+
--For databases both the primary and secondary, with send/receive counters reflecting the local replica
68+
select object_name,counter_name,instance_name,cntr_value
69+
from sys.dm_os_performance_counters
70+
where object_name like '%Availability Replica%' and instance_name <> '_Total' and
71+
( counter_name = 'Bytes Received from Replica/sec' --From the availability replica. Pings and status updates will generate network traffic even on databases with no user updates.
72+
or counter_name = 'Bytes Sent to Replica/sec' --Sent to the remote replica. On primary, sent to the secondary replica. On secondary, sent to the primary replica.
73+
or counter_name = 'Bytes Sent to Transport/sec' --Sent over the network to the remote replica. On primary, sent to the secondary replica. On secondary, sent to the primary replica.
74+
or counter_name = 'Flow Control Time (ms/sec)' --Time in milliseconds that log stream messages waited for send flow control, in the last second.
75+
or counter_name = 'Receives from Replica/Sec'
76+
or counter_name = 'Sends to Replica/Sec'
77+
78+
)
79+
80+
81+
--Only valid for databases in the secondary replica role
82+
select object_name,counter_name,instance_name,cntr_value
83+
from sys.dm_os_performance_counters
84+
where object_name like '%database replica%' and instance_name <> '_Total' and
85+
( counter_name = 'File Bytes Received/sec' --FILESTREAM data only
86+
or counter_name = 'Log Bytes Received/sec' --Amount of log records received by the secondary replica for the database in the last second.'
87+
or counter_name = 'Log remaining for undo' --The amount of log in kilobytes remaining to complete the undo phase.
88+
)
89+
*/

0 commit comments

Comments
 (0)