Skip to content

Commit

Permalink
initial
Browse files Browse the repository at this point in the history
  • Loading branch information
williamadba committed Jul 20, 2017
0 parents commit 6a15e13
Show file tree
Hide file tree
Showing 123 changed files with 9,431 additions and 0 deletions.
8 changes: 8 additions & 0 deletions ALLOW_PAGE_LOCKS.sql
@@ -0,0 +1,8 @@
select 'alter INDEX [' + i.name + '] ON [' + s.name + '].[' + o.name + '] SET (ALLOW_PAGE_LOCKS = ON) --this is default'
, * from sys.indexes i
inner join sys.objects o on i.object_id = o.object_id
inner join sys.schemas s on s.schema_id = o.schema_id
where allow_page_locks = 0
and o.is_ms_shipped = 0


140 changes: 140 additions & 0 deletions Add SQL Agent Failure Notifications job.sql
@@ -0,0 +1,140 @@
--TODO: Change the operator name dbadministrators@sparkhound.com
--TODO: Uncomment --EXEC (@TSQL) when confirmed

USE [msdb]
GO

--These jobs do not have a notify operator setting
select j.job_id, j.name, CategoryName = jc.name, j.enabled, j.description
, OwnerName = suser_sname(j.owner_sid), date_created,date_modified, j.notify_email_operator_id
from msdb.dbo.sysjobs j
inner join msdb.dbo.syscategories jc
on j.category_id = jc.category_id
where j.notify_email_operator_id = 0
and j.name not in ('syspolicy_purge_history')

DECLARE AddFailureNotifications CURSOR FAST_FORWARD
FOR
select convert(nvarchar(4000), '
EXEC msdb.dbo.sp_update_job @job_id=N'''+convert(varchar(64), job_id)+''', /*'+j.name+'*/
@notify_level_email=2,
@notify_email_operator_name=N''dbadministrators@sparkhound.com''')
from msdb.dbo.sysjobs j
where j.notify_email_operator_id = 0
and j.name not in ('syspolicy_purge_history')

declare @tsql nvarchar(4000) = null
OPEN AddFailureNotifications
FETCH NEXT FROM AddFailureNotifications
INTO @tsql

WHILE @@FETCH_STATUS = 0
BEGIN
EXEC (@TSQL)
SELECT @TSQL
FETCH NEXT FROM AddFailureNotifications
INTO @tsql
END

CLOSE AddFailureNotifications
DEALLOCATE AddFailureNotifications;

/*
--Change the operator name dbadministrators@sparkhound.com
--you may need to change the @server_name value below
USE [msdb]
GO
BEGIN TRANSACTION
DECLARE @ReturnCode INT
SELECT @ReturnCode = 0
IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'[Uncategorized (Local)]' AND category_class=1)
BEGIN
EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'[Uncategorized (Local)]'
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
END
DECLARE @jobId BINARY(16)
EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'Add Failure Notifications',
@enabled=1,
@notify_level_eventlog=2,
@notify_level_email=2,
@notify_level_netsend=0,
@notify_level_page=0,
@delete_level=0,
@description=N'Adds failure notification emails to any jobs that are created',
@category_name=N'[Uncategorized (Local)]',
@owner_login_name=N'sa',
@notify_email_operator_name=N'dbadministrators@sparkhound.com', @job_id = @jobId OUTPUT
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'tsql',
@step_id=1,
@cmdexec_success_code=0,
@on_success_action=1,
@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'USE [msdb]
GO
DECLARE AddFailureNotifications CURSOR FAST_FORWARD
FOR
select convert(nvarchar(4000), ''
EXEC msdb.dbo.sp_update_job @job_id=N''''''+convert(varchar(64), job_id)+'''''',
@notify_level_email=2,
@notify_level_netsend=2,
@notify_level_page=2,
@notify_email_operator_name=N''''dbadministrators@sparkhound.com'''''')
from msdb.dbo.sysjobs
where notify_email_operator_id = 0
declare @tsql nvarchar(4000) = null
OPEN AddFailureNotifications
FETCH NEXT FROM AddFailureNotifications
INTO @tsql
WHILE @@FETCH_STATUS = 0
BEGIN
EXEC (@TSQL)
FETCH NEXT FROM AddFailureNotifications
INTO @tsql
END',
@database_name=N'msdb',
@flags=4
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'nightly',
@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=20150216,
@active_end_date=99991231,
@active_start_time=200000,
@active_end_time=235959,
@schedule_uid=N'fd1a2b03-1e0b-487d-ac6f-9eac60fc4f6a'
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:
GO
*/
39 changes: 39 additions & 0 deletions Add SQL Agent Failure Notifications.sql
@@ -0,0 +1,39 @@
--TODO: Change the operator name sql.alerts@sparkhound.com
--TODO: Uncomment --EXEC (@TSQL) when confirmed


--These jobs do not have a notify operator setting
select j.job_id, j.name, CategoryName = jc.name, j.enabled, j.description
, OwnerName = suser_sname(j.owner_sid), date_created,date_modified, j.notify_email_operator_id
from msdb.dbo.sysjobs j
inner join msdb.dbo.syscategories jc
on j.category_id = jc.category_id
where j.notify_email_operator_id = 0
and j.name not in ('syspolicy_purge_history')

DECLARE AddFailureNotifications CURSOR FAST_FORWARD
FOR
select convert(nvarchar(4000), '
EXEC msdb.dbo.sp_update_job @job_id=N'''+convert(varchar(64), job_id)+''', /*'+j.name+'*/
@notify_level_email=2,
@notify_email_operator_name=N''sql.alerts@sparkhound.com''')
from msdb.dbo.sysjobs j
where j.notify_email_operator_id = 0
and j.name not in ('syspolicy_purge_history')

declare @tsql nvarchar(4000) = null
OPEN AddFailureNotifications
FETCH NEXT FROM AddFailureNotifications
INTO @tsql

WHILE @@FETCH_STATUS = 0
BEGIN
--EXEC (@TSQL)
SELECT @TSQL
FETCH NEXT FROM AddFailureNotifications
INTO @tsql
END

CLOSE AddFailureNotifications
DEALLOCATE AddFailureNotifications;

18 changes: 18 additions & 0 deletions Availability Groups/AG owner.sql
@@ -0,0 +1,18 @@
--should not be owned by named account!

SELECT ar.replica_server_name
,ag.name AS ag_name
,ar.owner_sid
,sp.name
FROM sys.availability_replicas ar
LEFT JOIN sys.server_principals sp
ON sp.sid = ar.owner_sid
INNER JOIN sys.availability_groups ag
ON ag.group_id = ar.group_id
WHERE ar.replica_server_name = SERVERPROPERTY('ServerName') ;

/*
ALTER AUTHORIZATION ON AVAILABILITY GROUP::[drAG1] to [sa] ;
*/
77 changes: 77 additions & 0 deletions Availability Groups/AG_Monitor.sql
@@ -0,0 +1,77 @@
--On a secondary replica, this view returns a row for every secondary database on the server instance.
--On the primary replica, this view returns a row for each primary database and an additional row for the corresponding secondary database.

--Updated WDA 20170622

IF NOT EXISTS (
SELECT @@SERVERNAME, *
FROM sys.dm_hadr_availability_replica_states rs
inner join sys.availability_databases_cluster dc
on rs.group_id = dc.group_id
WHERE is_local = 1
and role_desc = 'PRIMARY'
)
SELECT 'Recommend: Run This Script on Primary Replica';


declare @start_tick bigint, @start_cntr bigint

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.
from sys.dm_os_sys_info
cross apply sys.dm_os_performance_counters where counter_name like 'Log Bytes Flushed/sec%'

waitfor delay '00:00:02'

declare @end_tick bigint, @end_cntr bigint
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.
from sys.dm_os_sys_info
cross apply sys.dm_os_performance_counters where counter_name like 'Log Bytes Flushed/sec%'

declare @LogBytesFushed decimal(19,2)
set @LogBytesFushed = (@end_cntr - @start_cntr) / NULLIF(@end_tick - @start_tick,0)

select
Replica = ar.replica_server_name + ' ' + case when is_local = 1 then '(local)' else '' end
, Replica_Role = case when last_received_time is null then 'PRIMARY' ELSE 'SECONDARY ('+ar.secondary_role_allow_connections_desc+')' END
, DB = db_name(database_id)
, dm.synchronization_state_desc
, dm.synchronization_health_desc
, ar.availability_mode_desc
, ar.failover_mode_desc
, Suspended = case is_suspended when 1 then suspend_reason_desc else null end
, last_received_time
, last_commit_time
, redo_queue_size_mb = redo_queue_size/1024.
, 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
, Log_Send_Queue_RPO = dm.log_send_queue_size/NULLIF(@LogBytesFushed ,0) --Rate
, ar.backup_priority
, ar.modify_date
, ar.endpoint_url
, ar.read_only_routing_url
from sys.dm_hadr_database_replica_states dm
INNER JOIN sys.availability_replicas ar on dm.replica_id = ar.replica_id and dm.group_id = ar.group_id
ORDER BY DB, [Replica], Replica_Role
--WHERE db_name(database_id) = 'operations'

--SELECT log_reuse_wait_desc FROM sys.databases WHERE name = 'operations'

--Check for suspect pages (hopefully 0 rows returned)
--https://msdn.microsoft.com/en-us/library/ms191301.aspx
SELECT * FROM msdb.dbo.suspect_pages
WHERE (event_type <= 3);

--Check for autorepair events (hopefully 0 rows returned)
--https://msdn.microsoft.com/en-us/library/bb677167.aspx
select db = db_name(database_id)
, file_id
, page_id
, error_type
, page_status
, modification_time
from sys.dm_hadr_auto_page_repair order by modification_time desc


--https://msdn.microsoft.com/en-us/library/ff877972(v=sql.110).aspx
--https://msdn.microsoft.com/en-us/library/dn135338(v=sql.110).aspx
--https://blogs.msdn.microsoft.com/psssql/2013/09/23/interpreting-the-counter-values-from-sys-dm_os_performance_counters/
--https://msdn.microsoft.com/en-us/library/ms175048.aspx
89 changes: 89 additions & 0 deletions Availability Groups/AG_PerfMon_Counters.sql
@@ -0,0 +1,89 @@
declare @tempperfmon table (
[object_name] nchar (256) null,
counter_name nchar (256) null,
instance_name nchar (256) null,
cntr_value bigint null
, second_value bigint null
)

--For databases both the primary and secondary, with send/receive counters reflecting the local replica
insert into @tempperfmon ([object_name],counter_name,instance_name,cntr_value)
select [object_name],counter_name,instance_name,cntr_value
from sys.dm_os_performance_counters
where [object_name] like '%Availability Replica%' and instance_name <> '_Total' and
( 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.
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.
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.
or counter_name = 'Flow Control Time (ms/sec)' --Time in milliseconds that log stream messages waited for send flow control, in the last second.
or counter_name = 'Receives from Replica/Sec'
or counter_name = 'Sends to Replica/Sec'

)

insert into @tempperfmon ([object_name],counter_name,instance_name,cntr_value)
--Only valid for databases in the secondary replica role
select [object_name],counter_name,instance_name,cntr_value
from sys.dm_os_performance_counters
where [object_name] like '%database replica%' and instance_name <> '_Total' and
( counter_name = 'File Bytes Received/sec' --FILESTREAM data only
or counter_name = 'Log Bytes Received/sec' --Amount of log records received by the secondary replica for the database in the last second.'
or counter_name = 'Log remaining for undo' --The amount of log in kilobytes remaining to complete the undo phase.
)

WAITFOR DELAY '00:00:05'; --5s


--For databases both the primary and secondary, with send/receive counters reflecting the local replica
insert into @tempperfmon ([object_name],counter_name,instance_name,second_value)
select [object_name],counter_name,instance_name,cntr_value
from sys.dm_os_performance_counters
where [object_name] like '%Availability Replica%' and instance_name <> '_Total' and
( 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.
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.
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.
or counter_name = 'Flow Control Time (ms/sec)' --Time in milliseconds that log stream messages waited for send flow control, in the last second.
or counter_name = 'Receives from Replica/Sec'
or counter_name = 'Sends to Replica/Sec'

)

insert into @tempperfmon ([object_name],counter_name,instance_name,second_value)
--Only valid for databases in the secondary replica role
select [object_name],counter_name,instance_name,cntr_value
from sys.dm_os_performance_counters
where [object_name] like '%database replica%' and instance_name <> '_Total' and
( counter_name = 'File Bytes Received/sec' --FILESTREAM data only
or counter_name = 'Log Bytes Received/sec' --Amount of log records received by the secondary replica for the database in the last second.'
or counter_name = 'Log remaining for undo' --The amount of log in kilobytes remaining to complete the undo phase.
)

select
[object_name],counter_name,instance_name
, Observation = (max(second_value) - max(cntr_value)) /5.
from @tempperfmon
group by [object_name],counter_name,instance_name

/*
--For databases both the primary and secondary, with send/receive counters reflecting the local replica
select object_name,counter_name,instance_name,cntr_value
from sys.dm_os_performance_counters
where object_name like '%Availability Replica%' and instance_name <> '_Total' and
( 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.
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.
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.
or counter_name = 'Flow Control Time (ms/sec)' --Time in milliseconds that log stream messages waited for send flow control, in the last second.
or counter_name = 'Receives from Replica/Sec'
or counter_name = 'Sends to Replica/Sec'
)
--Only valid for databases in the secondary replica role
select object_name,counter_name,instance_name,cntr_value
from sys.dm_os_performance_counters
where object_name like '%database replica%' and instance_name <> '_Total' and
( counter_name = 'File Bytes Received/sec' --FILESTREAM data only
or counter_name = 'Log Bytes Received/sec' --Amount of log records received by the secondary replica for the database in the last second.'
or counter_name = 'Log remaining for undo' --The amount of log in kilobytes remaining to complete the undo phase.
)
*/

0 comments on commit 6a15e13

Please sign in to comment.