[ SQL Server ] Script – Lock Alert with Email

Publicado: abril 29, 2016 em Uncategorized
Tags:, ,

—————————————————–

— Criar procedure de verificação e envio de e-mail
— Alterar:
— @EmailRecipients
— @profilename

— Obs.: Deve estar configurado o Database Mail
—————————————————–

USE msdb
GO

CREATE procedure [dbo].[sp_lock_job] AS
BEGIN
create table #temp
(SPID int,
EventType nvarchar(30),
Parameters int,
EventInfo nvarchar(4000) )

DECLARE @EmailRecipients varchar(255)
SET @EmailRecipients = ‘dba@example.com’
DECLARE @profilename varchar(255)
SET @profilename = ‘DBAAlerts’

declare @spid varchar(100)
declare @blocked varchar(100)
declare @waittime int
declare @dbid int
DECLARE @dbname varchar(255)
DECLARE @vcSubject varchar(255)
DECLARE @vcMessage varchar(255)
DECLARE @SqlText varchar(4000)

Select top 1 @spid = spid,

@blocked = blocked,
@waittime = waittime/1000,
@dbid = dbid
from sys.sysprocesses
where blocked>0
and waittime > 300000
order by waittime desc

SELECT @dbname = DB_NAME(@dbid)

insert into #temp(EventType, Parameters, EventInfo)
exec (‘DBCC INPUTBUFFER(‘ + @blocked +’) WITH NO_INFOMSGS’)


select @SqlText = EventInfo from #temp

SET @vcSubject = @dbname + ‘: Lock Detected (> 5 min)’
SET @vcMessage = ‘A sessao ‘ + @blocked + ‘ encontra-se bloqueando a sessao ‘+ @spid +’.’ + CHAR(10) + CHAR(10) +
‘SQL utilizado: ‘ + CHAR(10) +
@SqlText

PRINT ‘Alert E-mail sent ‘

— Stored procedure used in SQL Server 2005
EXEC msdb.dbo.sp_send_dbmail
@profile_name = @profilename,
@recipients = @EmailRecipients,
@subject = @vcSubject,
@Body =@vcMessage

DROP TABLE #Temp
END

—————————————————–

— Criar Job para o envio de e-mail

— Obs.: Ligado ao Alert criado.
—————————————————–

USE [msdb]
GO

/****** Object: Job [Database Lock Detected (DBA)] Script Date: 04/28/2016 14:19:59 ******/
BEGIN TRANSACTION
DECLARE @ReturnCode INT
SELECT @ReturnCode = 0
/****** Object: JobCategory [DB Helth Monitoring] Script Date: 04/28/2016 14:19:59 ******/
IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N’DB Helth Monitoring’ AND category_class=1)
BEGIN
EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N’JOB’, @type=N’LOCAL’, @name=N’DB Helth Monitoring’
IF (@@ERROR 0 OR @ReturnCode 0) GOTO QuitWithRollback

END

DECLARE @jobId BINARY(16)
EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N’Database Lock Detected (DBA)’,
@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’DB Helth Monitoring’,
@owner_login_name=N’sa’, @job_id = @jobId OUTPUT
IF (@@ERROR 0 OR @ReturnCode 0) GOTO QuitWithRollback
/****** Object: Step [Enviar E-mail com Informações de Lock] Script Date: 04/28/2016 14:20:00 ******/
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N’Enviar E-mail com Informações de Lock’,
@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.sp_lock_job’,
@database_name=N’msdb’,
@database_user_name=N’sa’,
@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_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

—————————————————–

— Criar alert para o Wait Time do Lock > 300000 (5 minutos)

—————————————————–

USE [msdb]
GO

/****** Object: Alert [ Warning – Lock Wait Time is 5 minutes] Script Date: 04/28/2016 14:19:40 ******/
EXEC msdb.dbo.sp_add_alert @name=N’MTZSRVBANCO2 Warning – Lock Wait Time is 5 minutes’,
@message_id=0,
@severity=0,
@enabled=1,
@delay_between_responses=0,
@include_event_description_in=0,
@category_name=N'[Uncategorized]’,
@performance_condition=N’SQLServer:Locks|Lock Wait Time (ms)|_Total|>|300000′,
@job_name=N’Database Lock Detected (DBA)’
GO

Deixe uma resposta

Preencha os seus dados abaixo ou clique em um ícone para log in:

Logotipo do WordPress.com

Você está comentando utilizando sua conta WordPress.com. Sair / Alterar )

Imagem do Twitter

Você está comentando utilizando sua conta Twitter. Sair / Alterar )

Foto do Facebook

Você está comentando utilizando sua conta Facebook. Sair / Alterar )

Foto do Google+

Você está comentando utilizando sua conta Google+. Sair / Alterar )

Conectando a %s