CloudDB

11 de nov de 20193 min

SQL Server - Alerta Bloqueio por mais de 60 segundos

Atualizado: 12 de nov de 2019

Autoridade_SQL_Server_Alerta_Ajusta_Trace_Flag_Performance ajuda na questão. Como chegar em um ambiente novo e dar resultados rápidos? Melhores práticas? garantia de evitação de bugs?
 

 
O que funciona em mais de 10 mil Bancos de Dados, no mundo, funcionará no seu ambiente? Dúvidas? mentor@clouddbm.com
 

 
O objetivo do kit DB de mentoria é que você consiga ter um set mínimo de scripts que automatizam e garantam um benchmarking de Bancos de Dados e você vai personalizando até o resultado esperado, mesmo em Bancos de Dados com mais de 15 Terabytes em que você precisará analisar todos os "bit and bytes" para a escalabilidade, a melhor metodologia é essa! Concluo com 20 anos de experiência e mais de 15 certificações que existem sim "atalhos" para uma vida tranquila,
 
atuando em suporte, desde que você faça muito bem o "dever de casa":
 

 
https://support.microsoft.com/en-ae/help/974006/sql-server-query-optimizer-hotfix-trace-flag-4199-servicing-model
 
https://blogs.msdn.microsoft.com/psssql/2015/03/02/running-sql-server-on-machines-with-more-than-8-cpus-per-numa-node-may-need-trace-flag-8048/
 
https://www.brentozar.com/archive/2017/02/using-trace-flag-2453-improve-table-variable-performance/
 

 
Grato,
 

 
Gilberto Rosa
 
CEO and Founder at www.CloudDBM.com
 
MCITP/MCTS/MCSE/MCT

USE [msdb]
 
GO
 
/****** Object: StoredProcedure [dbo].[spu_alerta_bloqueio] Script Date: 11/26/2018 3:40:50 PM ******/
 
SET ANSI_NULLS ON
 
GO
 
SET QUOTED_IDENTIFIER ON
 
GO
 
CREATE proc [dbo].[spu_alerta_bloqueio] as
 

 
SET NOCOUNT ON
 

 
SELECT s.session_id
 
,r.STATUS
 
,r.blocking_session_id
 
,r.wait_type
 
,wait_resource
 
,r.wait_time / (1000.0) 'WaitSec'
 
,r.cpu_time
 
,r.logical_reads
 
,r.reads
 
,r.writes
 
,r.total_elapsed_time / (1000.0) 'ElapsSec'
 
,Substring(st.TEXT, (r.statement_start_offset / 2) + 1, (
 
(
 
CASE r.statement_end_offset
 
WHEN - 1
 
THEN Datalength(st.TEXT)
 
ELSE r.statement_end_offset
 
END - r.statement_start_offset
 
) / 2
 
) + 1) AS statement_text
 
,Coalesce(Quotename(Db_name(st.dbid)) + N'.' + Quotename(Object_schema_name(st.objectid, st.dbid)) + N'.' + Quotename(Object_name(st.objectid, st.dbid)), '') AS command_text
 
,r.command
 
,s.login_name
 
,s.host_name
 
,s.program_name
 
,s.host_process_id
 
,s.last_request_end_time
 
,s.login_time
 
,r.open_transaction_count
 
INTO #temp_requests
 
FROM sys.dm_exec_sessions AS s
 
INNER JOIN sys.dm_exec_requests AS r ON r.session_id = s.session_id
 
CROSS APPLY sys.dm_exec_sql_text(r.sql_handle) AS st
 
WHERE r.session_id != @@SPID
 
and r.wait_time / (1000.0) > 60
 
ORDER BY r.cpu_time DESC
 
,r.STATUS
 
,r.blocking_session_id
 
,s.session_id
 

 
IF (
 
SELECT count(*)
 
FROM #temp_requests
 
WHERE blocking_session_id > 50
 
) <> 0
 
BEGIN
 
-- blocking found, sent email.
 
DECLARE @tableHTML NVARCHAR(MAX);
 

 
SET @tableHTML = N'<H1>Aten��o - Bloqueios a mais de 1 minuto no Banco de Dados</H1>' + N'<table border="1">' + N'<tr>' + N'<th>session_id</th>' + N'<th>Status</th>' +
 
N'<th>blocking_session_id</th><th>wait_type</th><th>wait_resource</th>' +
 
N'<th>WaitSec</th>' + N'<th>cpu_time</th>' +
 
N'<th>logical_reads</th>' + N'<th>reads</th>' +
 
N'<th>writes</th>' + N'<th>ElapsSec</th>' + N'<th>statement_text</th>' + N'<th>command_text</th>' +
 
N'<th>command</th>' + N'<th>login_name</th>' + N'<th>host_name</th>' + N'<th>program_name</th>' +
 
N'<th>host_process_id</th>' + N'<th>last_request_end_time</th>' + N'<th>login_time</th>' +
 
N'<th>open_transaction_count</th>' + '</tr>' + CAST((
 
SELECT td = s.session_id
 
,''
 
,td = r.STATUS
 
,''
 
,td = r.blocking_session_id
 
,''
 
,td = r.wait_type
 
,''
 
,td = wait_resource
 
,''
 
,td = r.wait_time / (1000.0)
 
,''
 
,td = r.cpu_time
 
,''
 
,td = r.logical_reads
 
,''
 
,td = r.reads
 
,''
 
,td = r.writes
 
,''
 
,td = r.total_elapsed_time / (1000.0)
 
,''
 
,td = Substring(st.TEXT, (r.statement_start_offset / 2) + 1, (
 
(
 
CASE r.statement_end_offset
 
WHEN - 1
 
THEN Datalength(st.TEXT)
 
ELSE r.statement_end_offset
 
END - r.statement_start_offset
 
) / 2
 
) + 1)
 
,''
 
,td = Coalesce(Quotename(Db_name(st.dbid)) + N'.' + Quotename(Object_schema_name(st.objectid, st.dbid)) +
 
N'.' + Quotename(Object_name(st.objectid, st.dbid)), '')
 
,''
 
,td = r.command
 
,''
 
,td = s.login_name
 
,''
 
,td = s.host_name
 
,''
 
,td = s.program_name
 
,''
 
,td = s.host_process_id
 
,''
 
,td = s.last_request_end_time
 
,''
 
,td = s.login_time
 
,''
 
,td = r.open_transaction_count
 
FROM sys.dm_exec_sessions AS s
 
INNER JOIN sys.dm_exec_requests AS r ON r.session_id = s.session_id
 
CROSS APPLY sys.dm_exec_sql_text(r.sql_handle) AS st
 
WHERE r.session_id != @@SPID
 
AND blocking_session_id > 0
 
ORDER BY r.cpu_time DESC
 
,r.STATUS
 
,r.blocking_session_id
 
,s.session_id
 
FOR XML PATH('tr')
 
,TYPE
 
) AS NVARCHAR(MAX)) + N'</table>';
 

 
EXEC msdb.dbo.sp_send_dbmail @body = @tableHTML
 
,@body_format = 'HTML'
 
,@profile_name = N'E-MAIL 1'
 
,@recipients = N'monitoramento@clouddbm.com'
 
,@Subject = N'Bloqueio detectado - SERVIDOR BANCO DE DADOS'
 
END
 

 
DROP TABLE #temp_requests

    160
    0