select *
FROM sys.databases (nolock) AS DBS
INNER JOIN sys.dm_hadr_database_replica_states (Nolock) AS DBReplica
ON DBS.database_id = DBReplica.database_ID
WHERE DBReplica.is_primary_replica = 1 AND
( DBS.state <> 0) OR ( DBReplica.database_state_desc <> 'ONLINE')
Job
USE [msdb]
GO
/****** Object: Job [DBA - Primary Replica Health Check] Script Date: 3/25/2021 12:23:16 PM ******/
BEGIN TRANSACTION
DECLARE @ReturnCode INT
SELECT @ReturnCode = 0
/****** Object: JobCategory [AvailabilityGroup] Script Date: 3/25/2021 12:23:16 PM ******/
IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'AvailabilityGroup' AND category_class=1)
BEGIN
EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'AvailabilityGroup'
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
END
DECLARE @jobId BINARY(16)
EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'DBA - Primary Replica Health Check',
@enabled=1,
@notify_level_eventlog=0,
@notify_level_email=2,
@notify_level_netsend=0,
@notify_level_page=0,
@delete_level=0,
@description=N'Checks the health of all primary replicas on the server.',
@category_name=N'AvailabilityGroup',
@owner_login_name=N'sa',
@notify_email_operator_name=N'BATA DB Support', @job_id = @jobId OUTPUT
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
/****** Object: Step [Check for problems with primary database in AG] Script Date: 3/25/2021 12:23:16 PM ******/
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Check for problems with primary database in AG',
@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'DECLARE @ROWCOUNT Int
SET @ROWCOUNT = (select COUNT (*)
FROM sys.databases (nolock) AS DBS
INNER JOIN sys.dm_hadr_database_replica_states (Nolock) AS DBReplica
ON DBS.database_id = DBReplica.database_ID
WHERE DBReplica.is_primary_replica = 1 AND
( DBS.state <> 0) OR ( DBReplica.database_state_desc <> ''ONLINE'')
)
IF @ROWCOUNT > 0
BEGIN
RAISERROR (''PRIMARY REPLICA DATABASE PROBLEMS EXIST'' , 16, 1)
END
',
@database_name=N'master',
@flags=12
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
/****** Object: Step [Send out notification] Script Date: 3/25/2021 12:23:16 PM ******/
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Send out notification',
@step_id=2,
@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
BEGIN
DECLARE @cmd NVARCHAR(MAX)
SET @cmd = N''<H1>Problems with the following database(s) may exist:</H1>'' + N''<table border="1">''
+ N''<tr><th>Database Name</th>''
+ N''<th>Database State</th>''
+ N''<th>Synch Health Desc.</th>''
+ CAST ( ( SELECT td = DBS.name,
'''' ,
td = DBS.state_desc,
'''',
td = DBReplica.synchronization_health_desc ,
''''
FROM master.sys.databases (nolock) AS DBS
INNER JOIN master.sys.dm_hadr_database_replica_states (Nolock) AS DBReplica
ON DBS.database_id = DBReplica.database_id
where DBReplica.is_primary_replica = 1 AND ( DBS.state <> 0) OR ( DBReplica.database_state_desc <> ''ONLINE'')
FOR
XML PATH(''tr'') ,
TYPE
) AS NVARCHAR(MAX)) + N''</table>''
--== Set a variable to get our instance name. ==--
--== We do this so the email we receive makes more sense. ==--
DECLARE @servername NVARCHAR(150)
DECLARE @profilename NVARCHAR (50)
SET @servername = @@SERVERNAME
SET @profilename = (Select top 1 name from msdb.dbo.sysmail_profile)
--== We set another variable to create a subject line for the email. ==--
DECLARE @mysubject NVARCHAR(200)
SET @mysubject = ''Primary Replica Database Problem on '' + @servername
EXEC msdb.dbo.sp_send_dbmail @recipients = ''me@test.com'',
@profile_name = @profilename,
@subject = @mysubject,
@body = @cmd, @body_format = ''HTML'' ,@query_no_truncate = 1
END
',
@database_name=N'master',
@flags=12
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'Every 15 minutes',
@enabled=1,
@freq_type=4,
@freq_interval=1,
@freq_subday_type=4,
@freq_subday_interval=15,
@freq_relative_interval=0,
@freq_recurrence_factor=0,
@active_start_date=20141003,
@active_end_date=99991231,
@active_start_time=200,
@active_end_time=235959,
@schedule_uid=N'50ed4cff-7b12-4a15-9a29-a372b74d5892'
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
Comments