Home > Link, Microsoft SQL Server, MSBI, Optimization, Query, Script, SQL Mentalist, SQL PraRup, SQL Query, SQL Server, Technology,, TSQL, Vishal Pawar > BI SQL # 167 : SQL Server DBA Scripts : List all Locks of the Current Database

BI SQL # 167 : SQL Server DBA Scripts : List all Locks of the Current Database

Hi Folks,

In this article we are going to cover How to List all Locks of the Current Database.

In this post we are going to discuss following points:

  • Problem Statement of SQL Script:
  • Description of SQL Script:
  • SQL Script Output Column
  • SQL Script Code
  • User Level to execute

    Problem Statement of SQL Script:

    Find List of all Locks of the Current Database.

    Description of SQL Script:

    This Transact-SQL script list all locks with details currently existing in the selected database. With this script you can check exclusive locked object watching lock escalation during long running DML statements, e.g. from key to page to object lock watch what happens when you run a DBCC command like Index Defrag or Shrink Database which index is used to validate a (foreign key) constraint.

    SQL Script Output Column

    image

    SQL Script Code

    SELECT TL.resource_type AS ResType
        ,TL.resource_description AS ResDescr
        ,TL.request_mode AS ReqMode
        ,TL.request_type AS ReqType
        ,TL.request_status AS ReqStatus
        ,TL.request_owner_type AS ReqOwnerType
        ,TAT.[name] AS TransName
        ,TAT.transaction_begin_time AS TransBegin
        ,DATEDIFF(ss, TAT.transaction_begin_time, GETDATE()) AS 
        TransDura
        ,ES.session_id AS S_Id
        ,ES.login_name AS LoginName
        ,COALESCE(OBJ.NAME, PAROBJ.NAME) AS ObjectName
        ,PARIDX.NAME AS IndexName
        ,ES.host_name AS HostName
        ,ES.program_name AS ProgramName
    FROM sys.dm_tran_locks AS TL
    INNER JOIN sys.dm_exec_sessions AS ES ON TL.request_session_id = ES
        .session_id
    LEFT JOIN sys.dm_tran_active_transactions AS TAT ON TL.
        request_owner_id = TAT.transaction_id
        AND TL.request_owner_type = 'TRANSACTION'
    LEFT JOIN sys.objects AS OBJ ON TL.resource_associated_entity_id = 
        OBJ.object_id
        AND TL.resource_type = 'OBJECT'
    LEFT JOIN sys.partitions AS PAR ON TL.
        resource_associated_entity_id = PAR.hobt_id
        AND TL.resource_type IN (
            'PAGE'
            ,'KEY'
            ,'RID'
            ,'HOBT'
            )
    LEFT JOIN sys.objects AS PAROBJ ON PAR.object_id = PAROBJ.object_id
    LEFT JOIN sys.indexes AS PARIDX ON PAR.object_id = PARIDX.object_id
        AND PAR.index_id = PARIDX.index_id
    WHERE TL.resource_database_id = DB_ID()
        AND ES.session_id <> @@Spid -- Exclude "my" session 
        -- optional filter  
        AND TL.request_mode <> 'S' -- Exclude simple shared locks 
    ORDER BY TL.resource_type
        ,TL.request_mode
        ,TL.request_type
        ,TL.request_status
        ,ObjectName
        ,ES.login_name;

    User Level to execute

    200

    Hope you will like How to List all Locks of the Current Database.

    If you really like reading my blog and understood at least few thing then please don’t forget to subscribe my blog.

If you want daily link and analysis or interesting link go to following website which will give @ your inbox please subscribe our following link resource blog :

Link Resource Website

For More information related to BI World visit my Mentalist Blog

SQL Server Mentalist >> SQL Learning Blog

Business Intelligence Mentalist >> BI World

Infographic Mentalist >> Image worth explaining thousand Words

Microsoft Mentalist >> MVC,ASP.NET, WCF & LinQ

DBA Mentalist >>Advance SQL Server Blog

Microsoft BI Mentalist >> MS BI Development Update

Connect With me on

| FaceBook |Twitter | linkedIn| Google+ | WordPress | RSS |

Advertisement
  1. No comments yet.
  1. No trackbacks yet.

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out /  Change )

Twitter picture

You are commenting using your Twitter account. Log Out /  Change )

Facebook photo

You are commenting using your Facebook account. Log Out /  Change )

Connecting to %s

%d bloggers like this: