Locks

  • DATE/TIME:2/19/2011 8:35:51 PM

    DESCRIPTION:The SQL Server performance counter 'Lock Wait Time (ms)' (instance '_Total') of object 'SQLServer:Locks' is now above the threshold of 30.00 (the current value is 141.40).

    COMMENT:(None)

    JOB RUN:(None)

    I configured alert for locks occurs more than 30 seconds on instance_total. please tell me, how to capture particular locks SPID & transaction statement?

    thanks

    ananda

  • CREATE PROC [dbo].[dba_WhatSQLIsExecuting]

    AS

    /*--------------------------------------------------------------------

    Purpose: Shows what individual SQL statements are currently executing.

    ----------------------------------------------------------------------

    Parameters: None.

    Revision History:

    24/07/2008 Ian_Stirk@yahoo.com Initial version

    Example Usage:

    1. exec YourServerName.master.dbo.dba_WhatSQLIsExecuting

    ---------------------------------------------------------------------*/

    BEGIN

    -- Do not lock anything, and do not get held up by any locks.

    SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED

    -- What SQL Statements Are Currently Running?

    SELECT [Spid] = session_Id

    , ecid

    , [Database] = DB_NAME(sp.dbid)

    , [User] = nt_username

    , [Status] = er.status

    , [Wait] = wait_type

    , [Individual Query] = SUBSTRING (qt.text,

    er.statement_start_offset/2,

    (CASE WHEN er.statement_end_offset = -1

    THEN LEN(CONVERT(NVARCHAR(MAX), qt.text)) * 2

    ELSE er.statement_end_offset END -

    er.statement_start_offset)/2)

    ,[Parent Query] = qt.text

    , Program = program_name

    , Hostname

    , nt_domain

    , start_time

    FROM sys.dm_exec_requests er

    INNER JOIN sys.sysprocesses sp ON er.session_id = sp.spid

    CROSS APPLY sys.dm_exec_sql_text(er.sql_handle)as qt

    WHERE session_Id > 50 -- Ignore system spids.

    AND session_Id NOT IN (@@SPID) -- Ignore this current statement.

    ORDER BY 1, 2

    END

  • Here is a good link and a query from that link I have found very useful:

    http://www.simple-talk.com/sql/database-administration/investigating-transactions-using-dynamic-management-objects/

    --Assessing transaction log impact

    --http://www.simple-talk.com/sql/database-administration/investigating-transactions-using-dynamic-management-objects/

    SELECT

    DTST.[session_id],

    DES.[login_name] AS [Login Name],

    DES.[program_name] AS [Program Name],

    DB_NAME (DTDT.database_id) AS [Database],

    DTDT.[database_transaction_begin_time] AS [Begin Time],

    DATEDIFF(ms,DTDT.[database_transaction_begin_time], GETDATE()) AS [Duration ms],

    CASE DTAT.transaction_type

    WHEN 1 THEN 'Read/write'

    WHEN 2 THEN 'Read-only'

    WHEN 3 THEN 'System'

    WHEN 4 THEN 'Distributed'

    END AS [Transaction Type],

    CASE DTAT.transaction_state

    WHEN 0 THEN 'Not fully initialized'

    WHEN 1 THEN 'Initialized, not started'

    WHEN 2 THEN 'Active'

    WHEN 3 THEN 'Ended'

    WHEN 4 THEN 'Commit initiated'

    WHEN 5 THEN 'Prepared, awaiting resolution'

    WHEN 6 THEN 'Committed'

    WHEN 7 THEN 'Rolling back'

    WHEN 8 THEN 'Rolled back'

    END AS [Transaction State],

    DTDT.[database_transaction_log_record_count] AS [Log Records],

    DTDT.[database_transaction_log_bytes_used] AS [Log Bytes Used],

    DTDT.[database_transaction_log_bytes_reserved] AS [Log Bytes RSVPd],

    DEST.[text] AS [Last Transaction Text],

    DEQP.[query_plan] AS [Last Query Plan]

    FROM

    sys.dm_tran_database_transactions DTDT

    INNER JOIN

    sys.dm_tran_session_transactions DTST

    ON

    DTST.[transaction_id] = DTDT.[transaction_id]

    INNER JOIN

    sys.[dm_tran_active_transactions] DTAT

    ON

    DTST.[transaction_id] = DTAT.[transaction_id]

    INNER JOIN

    sys.[dm_exec_sessions] DES

    ON

    DES.[session_id] = DTST.[session_id]

    INNER JOIN

    sys.dm_exec_connections DEC

    ON

    DEC.[session_id] = DTST.[session_id]

    LEFT JOIN

    sys.dm_exec_requests DER

    ON

    DER.[session_id] = DTST.[session_id]

    CROSS APPLY

    sys.dm_exec_sql_text (DEC.[most_recent_sql_handle]) AS DEST

    OUTER APPLY

    sys.dm_exec_query_plan (DER.[plan_handle]) AS DEQP

    ORDER BY

    [Duration ms] DESC;

    __________________________________________________________________________________
    SQL Server 2016 Columnstore Index Enhancements - System Views for Disk-Based Tables[/url]
    Persisting SQL Server Index-Usage Statistics with MERGE[/url]
    Turbocharge Your Database Maintenance With Service Broker: Part 2[/url]

Viewing 3 posts - 1 through 2 (of 2 total)

You must be logged in to reply to this topic. Login to reply