Monitor Log Shipping Script

Having multiple databases being log shipped could become a nightmare to monitor. The native SQL Monitor will just send too many emails and flood your mailbox.

The following Script will create a stored procedure to monitor Log Shipping replication, and send a summary of all databases that fall behind a threshold. It takes the input parameter “@time”, and makes sure that you do not receive too many emails.

 

SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
-- =============================================
-- Author: DBASVC
-- Description: Monitor Log Shipping
-- =============================================
CREATE PROCEDURE [dbo].[LS_Monitor]
@time DATETIME = 60  -- Set threshold for Alerts
AS
BEGIN
DECLARE @now DATETIME = GETDATE()
DECLARE @diff DATETIME = @now - '1900-01-01 00:45:00'
SET NOCOUNT ON;
CREATE TABLE #LSMonitor
(
[status] BIT NULL
,[is_primary] BIT NOT NULL DEFAULT 0
,[server] SYSNAME
,[database_name] SYSNAME
,[time_since_last_backup] INT NULL
,[last_backup_file] NVARCHAR(500) NULL
,[backup_threshold] INT NULL
,[is_backup_alert_enabled] BIT NULL
,[time_since_last_copy] INT NULL
,[last_copied_file] NVARCHAR(500) NULL
,[time_since_last_restore] INT NULL
,[last_restored_file] NVARCHAR(500) NULL
,[last_restored_latency] INT NULL
,[restore_threshold] INT NULL
,[is_restore_alert_enabled] BIT NULL
,PRIMARY KEY ([is_primary], [server], [database_name])
)
INSERT INTO #LSMonitor
EXEC master.sys.sp_help_log_shipping_monitor
IF EXISTS (SELECT TOP 1 1 FROM #LSMonitor WHERE time_since_last_restore > @time )
BEGIN
IF NOT EXISTS (SELECT TOP 100 *
FROM msdb.dbo.sysmail_allitems
WHERE [subject] = 'Log Shipping latency for DR'
AND sent_date > @diff)
BEGIN
DECLARE @tableHTML NVARCHAR(MAX) ;
SET @tableHTML =
N'
<H3>Log Shipping Latency for DR Servers</H3>
' +
N'
<table border="1">' +
N'
<tr>
<th>ServerName</th>
<th>Minutes_since_last_restore</th>
' +
N'
<th>Database_name</th>
<th>Last_restored_file</th>
</tr>
' +
CAST ( ( SELECT td = [server] , '',
td = Time_since_last_restore , '',
td = [Database_name] , '',
td = Last_restored_file , ''
FROM #LSMonitor
WHERE time_since_last_restore > @time
FOR XML PATH('tr'), TYPE
) AS NVARCHAR(MAX) ) +
N'</table>
' ;
EXEC msdb.dbo.sp_send_dbmail
@profile_name = 'DBAs',
@recipients = 'dbms_dba@dbasvc.com',
@body = @tableHTML,
@subject = 'Log Shipping latency for DR',
@body_format = 'HTML'

END
END
DROP TABLE #LSMonitor
END
GO

 

It is recommended to set a job to execute the stored procedure every certain amount of time.

USE [msdb]
GO
/****** Object: Job [LS_Monitor_LogShipping_DR] Script Date: 5/9/2019 4:49:46 PM ******/
BEGIN TRANSACTION
DECLARE @ReturnCode INT
SELECT @ReturnCode = 0
/****** Object: JobCategory [[Uncategorized (Local)]] Script Date: 5/9/2019 4:49:46 PM ******/
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'LS_Monitor_LogShipping_DR',
@enabled=1,
@notify_level_eventlog=0,
@notify_level_email=0,
@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', @job_id = @jobId OUTPUT
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
/****** Object: Step [1] Script Date: 5/9/2019 4:49:46 PM ******/
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'1',
@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'exec dbo.LS_Monitor',
@database_name=N'DBA',
@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'1',
@enabled=1,
@freq_type=4,
@freq_interval=1,
@freq_subday_type=4,
@freq_subday_interval=2,
@freq_relative_interval=0,
@freq_recurrence_factor=0,
@active_start_date=20190424,
@active_end_date=99991231,
@active_start_time=0,
@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:
GO