Dicas para um DBA Iniciante – Listando detalhes sobre conexões no SQL Server
By Vitor Fava
E ai pessoal, tudo bem?
Hoje quero compartilhar um script muito interessante que necessitei utilizar em uma situação na qual precisava listar detalhes das conexões abertar com um servidor de banco de dados SQL Server e quais os erros que cada conexão estava recebendo.
Para conseguir essas informações utilizei a sessão system_health do extended events, lendo as informações disponíveis no RING BUFFER.
Declare @LanguageID int; Select @LanguageID = lcid From sys.syslanguages Where name = @@Language; WITH RingBufferXML As (SELECT CAST(record as xml) AS RecordXML FROM sys.dm_os_ring_buffers WHERE ring_buffer_type= 'RING_BUFFER_CONNECTIVITY'), RingBufferConnectivity As (SELECT x.y.value('(/Record/@id)[1]', 'int') AS [RecordID], x.y.value('(/Record/ConnectivityTraceRecord/RecordType)[1]', 'varchar(max)') AS RecordType, x.y.value('(/Record/ConnectivityTraceRecord/RecordTime)[1]', 'datetime') AS RecordTime, x.y.value('(/Record/ConnectivityTraceRecord/SniConsumerError)[1]', 'int') AS Error, x.y.value('(/Record/ConnectivityTraceRecord/State)[1]', 'int') AS State, x.y.value('(/Record/ConnectivityTraceRecord/Spid)[1]', 'int') AS SPID, x.y.value('(/Record/ConnectivityTraceRecord/RemoteHost)[1]', 'varchar(max)') AS RemoteHost, x.y.value('(/Record/ConnectivityTraceRecord/RemotePort)[1]', 'varchar(max)') AS RemotePort, x.y.value('(/Record/ConnectivityTraceRecord/LocalHost)[1]', 'varchar(max)') AS LocalHost, x.y.value('(/Record/ConnectivityTraceRecord/LoginTimersInMilliseconds/TotalTime)[1]', 'int') AS TotalTime, x.y.value('(/Record/ConnectivityTraceRecord/LoginTimersInMilliseconds/EnqueueTime)[1]', 'int') AS EnqueueTime, x.y.value('(/Record/ConnectivityTraceRecord/LoginTimersInMilliseconds/NetWritesTime)[1]', 'int') AS NetWritesTime, x.y.value('(/Record/ConnectivityTraceRecord/LoginTimersInMilliseconds/NetReadsTime)[1]', 'int') AS NetReadsTime, x.y.value('(/Record/ConnectivityTraceRecord/LoginTimersInMilliseconds/Ssl/TotalTime)[1]', 'int') AS SslTotalTime, x.y.value('(/Record/ConnectivityTraceRecord/LoginTimersInMilliseconds/Sspi/TotalTime)[1]', 'int') AS SspiTotalTime, x.y.value('(/Record/ConnectivityTraceRecord/LoginTimersInMilliseconds/TriggerAndResGovTime)[1]', 'int') AS TriggerAndResGovTime FROM RingBufferXML CROSS APPLY RecordXML.nodes('//Record') AS x(y)) SELECT RBC.*, m.text FROM RingBufferConnectivity RBC LEFT JOIN sys.messages M ON RBC.Error = M.message_id AND M.language_id = @LanguageID WHERE RBC.RecordType IN ('Error', 'LoginTimers') ORDER BY RBC.RecordTime DESC;
Espero que gostem e não deixem de inscreverem-se no blog, no canal do youtube, no grupo de discussão SQLManiacs e em nosso grupo no TELEGRAM.
Grande abraço a todos.
Fonte: Vitor Fava