I got a task to automate replication monitoring in my environment. So I created a procedure and called it from a job every 5 mins.
If there is latency ,This Procedure sent mail to dba team with latency details , job , and where exactly latency exists.
\**********************************************/
Create Procedure Replication_Latency_Monitoring ( @minutes int)
As
Begin
/*****************************************
Created By: Saurabh Sinha
Created Date: 05/05/2015
Details: This check Latency in sql server replication set for 5 mins
**********************************************/
--declare @minutes int
--set @minutes = 5 --> Here is where you define how many minutes latency you would like to be notified
declare @threshold int
set @threshold = @minutes * 60 * 1000
--Specify email distribution list, To and CC
declare @Tolist varchar(100)
----declare @CClist varchar(100)
set @Tolist = 'Team Mail ID for Distibution'
----set @CClist = 'GTS.BANGALORE.DATABASE@ajg.com'
set @mailsubject = @@SERVERNAME + ' Replication Latency'
if exists (
select top 1 1 from sys.dm_os_performance_counters where object_name like '%Replica%'
and counter_name like '%Logreader:%latency%' and cntr_value > @threshold
union
select top 1 1 from sys.dm_os_performance_counters where object_name like '%Replica%'
and counter_name like '%Dist%latency%' and cntr_value > @threshold)
begin
DECLARE @tableHTML NVARCHAR(MAX) ;
SET @tableHTML =
N'<H1>'+@@SERVERNAME+' Replication Latency</H1>' +
N'<table border="1">' +
N'<tr><th>Agent</th><th>Latency Detail</th>' +
N'<th>JOB</th><th>latency in sec</th>' +
CAST ( ( SELECT td = object_name, '',
td = counter_name, '',
td = instance_name, '',
td = latency_sec, ''
FROM
(select object_name, counter_name, instance_name, round(cntr_value/1000,0) as latency_sec from sys.dm_os_performance_counters where object_name like '%Replica%'
and counter_name like '%Logreader:%latency%' and cntr_value > @threshold
union
select object_name, counter_name, instance_name, round(cntr_value/1000,0) as latency_sec from sys.dm_os_performance_counters where object_name like '%Replica%'
and counter_name like '%Dist%latency%' and cntr_value > @threshold) a
FOR XML PATH('tr'), TYPE
) AS NVARCHAR(MAX) ) +
N'</table>' ;
exec msdb.dbo.sp_send_dbmail
@recipients= @Tolist,
---- @copy_recipients = @CClist,
@subject = @mailsubject ,
@body_format ='HTML',
@body = @tableHTML
END
END
----------------------------------------------------------------
USE [msdb]
GO
/****** Object: Job [_AJGDBA_Replication_Latency_Monitoring] Script Date: 05/14/2015 12:17:29 ******/
BEGIN TRANSACTION
DECLARE @ReturnCode INT
SELECT @ReturnCode = 0
/****** Object: JobCategory [[Uncategorized (Local)]]] Script Date: 05/14/2015 12:17:29 ******/
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'Replication_Latency_Monitoring',
@enabled=1,
@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'[Uncategorized (Local)]',
@owner_login_name=N'sa',
@notify_email_operator_name=N'Add Operator Name', @job_id = @jobId OUTPUT
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
/****** Object: Step [Check Latency] Script Date: 05/14/2015 12:17:30 ******/
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Check Latency',
@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'<Database Name>.dbo.Replication_Latency_Monitoring @minutes = 5',
@database_name=N'<Database Name>',
@output_file_name=N'C:\Replication_latency_JOB.txt',
@flags=2
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'Replication_Latency_Monitoring',
@enabled=1,
@freq_type=4,
@freq_interval=1,
@freq_subday_type=4,
@freq_subday_interval=5,
@freq_relative_interval=0,
@freq_recurrence_factor=0,
@active_start_date=20150505,
@active_end_date=99991231,
@active_start_time=0,
@active_end_time=235959,
@schedule_uid=N'ca226490-cf40-4e5f-ae64-ae4bb06c2b84'
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
/******************Code END *********************/
No comments:
Post a Comment