Jaa


sys.dm_tran_locks

Returns information about currently active lock manager resources. Each row represents a currently active request to the lock manager for a lock that has been granted or is waiting to be granted.

The columns in the result set are divided into two main groups: resource and request. The resource group describes the resource on which the lock request is being made, and the request group describes the lock request.

Column name Data type Description

resource_type

nvarchar(120)

Represents the resource type. The value can be one of the following: DATABASE, FILE, OBJECT, PAGE, KEY, EXTENT, RID, APPLICATION, METADATA, HOBT, or ALLOCATION_UNIT.

resource_subtype

nvarchar(120)

Represents a subtype of resource_type. Acquiring a subtype lock without holding a nonsubtyped lock of the parent type is technically valid. Different subtypes do not conflict with each other or with the nonsubtyped parent type. Not all resource types have subtypes.

resource_database_id

int

ID of the database under which this resource is scoped. All resources handled by the lock manager are scoped by the database ID.

resource_description

nvarchar(512)

Description of the resource that contains only information that is not available from other resource columns.

resource_associated_entity_id

bigint

ID of the entity in a database with which a resource is associated. This can be an object ID, Hobt ID, or an Allocation Unit ID, depending on the resource type.

resource_lock_partition

int

ID of the lock partition for a partitioned lock resource. The value for nonpartitioned lock resources is 0.

request_mode

nvarchar(120)

Mode of the request. For granted requests, this is the granted mode; for waiting requests, this is the mode being requested.

request_type

nvarchar(120)

Request type. The value is LOCK.

request_status

nvarchar(120)

Current status of this request. Possible values are GRANTED, CONVERT, or WAIT.

request_reference_count

smallint

Returns an approximate number of times the same requestor has requested this resource.

request_lifetime

int

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

request_session_id

int

Session ID that currently owns this request. The owning session ID can change for distributed and bound transactions. A value of -2 indicates that the request belongs to an orphaned distributed transaction. A value of -3 indicates that the request belongs to a deferred recovery transaction, such as, a transaction for which a rollback has been deferred at recovery because the rollback could not be completed successfully.

request_exec_context_id

int

Execution context ID of the process that currently owns this request.

request_request_id

int

Request ID (batch ID) of the process that currently owns this request. This value will change every time that the active Multiple Active Result Set (MARS) connection for a transaction changes.

request_owner_type

nvarchar(120)

Entity type that owns the request. Lock manager requests can be owned by a variety of entities. Possible values are:

TRANSACTION = The request is owned by a transaction.

CURSOR = The request is owned by a cursor.

SESSION = The request is owned by a user session.

SHARED_TRANSACTION_WORKSPACE = The request is owned by the shared part of the transaction workspace.

EXCLUSIVE_TRANSACTION_WORKSPACE = The request is owned by the exclusive part of the transaction workspace.

request_owner_id

bigint

ID of the specific owner of this request. This value is only used for transactions for which this is the transaction ID.

request_owner_guid

uniqueidentifier

GUID of the specific owner of this request. This value is only used by a distributed transaction where the value corresponds to the MS DTC GUID for that transaction.

request_owner_lockspace_id

nvarchar(64)

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed. This value represents the lockspace ID of the requestor. The lockspace ID determines whether two requestors are compatible with each other and can be granted locks in modes that would otherwise conflict with one another.

lock_owner_address

varbinary(8)

Memory address of the internal data structure that is used to track this request. This column can be joined the with resource_address column in sys.dm_os_waiting_tasks.

Permissions

Requires VIEW SERVER STATE permission on the server.

Remarks

A granted request status indicates that a lock has been granted on a resource to the requestor. A waiting request indicates that the request has not yet been granted. The following waiting-request types are returned by the request_status column:

  • A convert request status indicates that the requestor has already been granted a request for the resource and is currently waiting for an upgrade to the initial request to be granted.
  • A wait request status indicates that the requestor does not currently hold a granted request on the resource.

Because sys.dm_tran_locks is populated from internal lock manager data structures, maintaining this information does not add extra overhead to regular processing. Materializing the view does require access to the lock manager internal data structures. This can have minor effects on the regular processing in the server. These effects should be unnoticeable and should only affect heavily used resources. Because the data in this view corresponds to live lock manager state, the data can change at any time, and rows are added and removed as locks are acquired and released. This view has no historical information.

Two requests operate on the same resource only if all the resource-group columns are equal.

You can control the locking of read operations by using the following tools:

A resource that is running under one session ID can have more than one granted lock. Different entities that are running under one session can each own a lock on the same resource, and the information is displayed in the request_owner_type and request_owner_id columns that are returned by sys.dm_tran_locks. If multiple instances of the same request_owner_type exist, the request_owner_id column is used to distinguish each instance. For distributed transactions, the request_owner_type and the request_owner_guid columns will show the different entity information.

For example, Session S1 owns a shared lock on Table1; and transaction T1, which is running under session S1, also owns a shared lock on Table1. In this case, the resource_description column that is returned by sys.dm_tran_locks will show two instances of the same resource. The request_owner_type column will show one instance as a session and the other as a transaction. Also, the resource_owner_id column will have different values.

Note

Multiple cursors that run under one session are indistinguishable and are treated as one entity. For more information about the types of locks used by the SQL Server Database Engine, see Locking in the Database Engine.

Distributed transactions that are not associated with a session ID value are orphaned transactions and are assigned the session ID value of -2. For more information, see KILL (Transact-SQL).

Resource Details

The following table lists the resources that are represented in the resource_associated_entity_id column.

Resource type Resource description Resource_associated_entity_id

DATABASE

Represents a database.

Not applicable

FILE

Represents a database file. This file can be either a data or a log file.

Not applicable

OBJECT

Represents a database object. This object can be a data table, view, stored procedure, extended stored procedure, or any object that has an object ID.

Object ID

PAGE

Represents a single page in a data file.

HoBt ID. This value corresponds to sys.partitions.hobt_id. The HoBt ID is not always available for PAGE resources because the HoBt ID is extra information that can be provided by the caller, and not all callers can provide this information.

KEY

Represents a row in an index.

HoBt ID. This value corresponds to sys.partitions.hobt_id.

EXTENT

Represents a data file extent. An extent is a group of eight contiguous pages.

Not applicable

RID

Represents a physical row in a heap.

HoBt ID. This value corresponds to sys.partitions.hobt_id. The HoBt ID is not always available for RID resources because the HoBt ID is extra information that can be provided by the caller, and not all callers can provide this information.

APPLICATION

Represents an application specified resource.

Not applicable

METADATA

Represents metadata information.

Not applicable

HOBT

Represents a heap or a B-tree. These are the basic access path structures.

HoBt ID. This value corresponds to sys.partitions.hobt_id.

ALLOCATION_UNIT

Represents a set of related pages, such as an index partition. Each allocation unit covers a single Index Allocation Map (IAM) chain.

Allocation Unit ID. This value corresponds to sys.allocation_units.allocation_unit_id.

The following table lists the subtypes that are associated with each resource type.

ResourceSubType Synchronizes

DATABASE.BULKOP_BACKUP_DB

Database backups with bulk operations.

DATABASE.BULKOP_BACKUP_LOG

Database log backups with bulk operations.

DATABASE.DDL

Data definition language (DDL) operations with file group operations, such as drop.

DATABASE.STARTUP

Used for database startup synchronization.

TABLE.UPDSTATS

Statistics updates on a table.

TABLE.COMPILE

Stored procedure compile.

TABLE.INDEX_OPERATION

Index operations.

HOBT.INDEX_REORGANIZE

Heap or index reorganization operations.

HOBT.BULK_OPERATION

Heap-optimized bulkload operations with concurrent scan, under these isolation levels: snapshot, read uncommitted, and read committed using row versioning.

ALLOCATION_UNIT.PAGE_COUNT

Allocation unit page count statistics during deferred drop operations.

METADATA.INDEXSTATS

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.STATS

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.XML_COLLECTION

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.SEQUENCE

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.QNAME

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.ASSEMBLY_CLR_NAME

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.ASSEMBLY_TOKEN

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.ASSEMBLY

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.PARTITION_FUNCTION

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.DATA_SPACE

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.USER_TYPE

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.DB_PRINCIPAL_SID

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.DATABASE_PRINCIPAL

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.SCHEMA

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.XML_COMPONENT

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.SERVER

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.INSTANTIATED_TYPE_HASH

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.DB_MIRRORING_SESSION

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.ENDPOINT

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.SECURITY_CACHE

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.DB_MIRRORING_WITNESS

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.CREDENTIAL

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.SECURITY_DESCRIPTOR

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.SERVICE_BROKER_GUID

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.CONVERSTATION_ENDPOINT_RECV

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.DATABASE

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.CONVERSATION_GROUP

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.ENDPOINT_WEBMETHOD

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.ASSYMMETRIC_KEY

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.FULLTEXT_CATALOG

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.FULLTEXT_INDEX

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.SERVER_PRINCIPAL

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.ROUTE

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.MESSAGE

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.QNAME_HASH

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.SERVICE_MESSAGE_TYPE

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.CONVERSTATION_ENDPOINT_SEND

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.CERTIFICATE

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.SYMMETRIC_KEY

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.XML_INDEX_QNAME

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.SERVICE_CONTRACT

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.REMOTE_SERVICE_BINDING

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.SERVICE

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.METADATA_CACHE

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

The following table provides the format of the resource_description column for each resource type.

Resource Format Description

DATABASE

Not applicable

Database ID is already available in the resource_database_id column.

FILE

<file_id>

ID of the file that is represented by this resource.

OBJECT

<object_id>

ID of the object that is represented by this resource. This object can be any object listed in sys.objects, not just a table.

PAGE

<file_id>:<page_in_file>

Represents the file and page ID of the page that is represented by this resource.

KEY

<hash_value>

Represents a hash of the key columns from the row that is represented by this resource.

EXTENT

<file_id>:<page_in_files>

Represents the file and page ID of the extent that is represented by this resource. The extent ID is the same as the page ID of the first page in the extent.

RID

<file_id>:<page_in_file>:<row_on_page>

Represents the page ID and row ID of the row that is represented by this resource. Note that if the associated object ID is 99, this resource represents one of the eight mixed page slots on the first IAM page of an IAM chain.

APPLICATION

<DbPrincipalId>:<upto 32 characters>:(<hash_value>)

Represents the ID of the database principal that is used for scoping this application lock resource. Also included are up to 32 characters from the resource string that corresponds to this application lock resource. In certain cases, only 2 characters can be displayed due to the full string no longer being available. This behavior occurs only at database recovery time for application locks that are reacquired as part of the recovery process. The hash value represents a hash of the full resource string that corresponds to this application lock resource.

HOBT

Not applicable

HoBt ID is included as the resource_associated_entity_id.

ALLOCATION_UNIT

Not applicable

Allocation Unit ID is included as the resource_associated_entity_id.

METADATA.SEQUENCE

$seq_type = S, object_id = O

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.STATS

object_id = O, stats_id = S

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.SCHEMA

schema_id = S

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.INDEXSTATS

object_id = O, index_id or stats_id = I

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.DATABASE_PRINCIPAL

principal_id = P

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.DB_PRINCIPAL_SID

$hash = H1:H2:H3

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.USER_TYPE

user_type_id = U

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.DATA_SPACE

data_space_id = D

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.PARTITION_FUNCTION

function_id = F

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.PARTITION_FUNCTION

function_id = F

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.ASSEMBLY

assembly_id = A

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.ASSEMBLY_TOKEN

assembly_id = A, $token_id = T

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.ASSEMBLY_CLR_NAME

$qname_id = Q

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.QNAME

$qname_id = Q

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.XML_COLLECTION

xml_collection_id = X

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.XML_COMPONENT

xml_component_id = X

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.QNAME_HASH

$qname_scope_id = Q, $qname_hash = H

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.XML_INDEX_QNAME

object_id = O, $qname_id = Q

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.SERVICE_MESSAGE_TYPE

message_type_id = M

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.SERVICE_CONTRACT

service_contract_id = S

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.SERVICE

service_id = S

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.REMOTE_SERVICE_BINDING

remote_service_binding_id = R

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.ROUTE

route_id = R

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.FULLTEXT_INDEX

object_id = O

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.FULLTEXT_CATALOG

fulltext_catalog_id = F

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.CONVERSATION_GROUP

conversation_group_id = C

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.CONVERSTATION_ENDPOINT_SEND

$hash = H1:H2:H3

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.CONVERSTATION_ENDPOINT_RECV

$hash = H1:H2:H3

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.SYMMETRIC_KEY

symmetric_key_id = S

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.CERTIFICATE

certificate_id = C

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.ASSYMMETRIC_KEY

asymmetric_key_id = A

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.DATABASE

database_id = D

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.MESSAGE

message_id = M

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.SERVER_PRINCIPAL

principal_id = P

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.SERVER

server_id = S

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.ENDPOINT

endpoint_id = E

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.ENDPOINT_WEBMETHOD

$hash = H1:H2:H3

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.DB_MIRRORING_SESSION

database_id = D

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.DB_MIRRORING_WITNESS

$hash = H1:H2:H3

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.SERVICE_BROKER_GUID

$hash = H1:H2:H3

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.SERVICE_BROKER_GUID

$hash = H1:H2:H3

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.CREDENTIAL

credential_id = C

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.INSTANTIATED_TYPE_HASH

user_type_id = U, hash = H1

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.SECURITY_DESCRIPTOR

sd_id = S

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.SECURITY_CACHE

$hash = H1:H2:H3

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

METADATA.METADATA_CACHE

$hash = H1:H2:H3

Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.

Examples

A. Using sys.dm_tran_locks with other tools

The following code example works with a scenario in which an update operation is blocked by another transaction. By using sys.dm_tran_locks and other tools, information about locking resources is provided.

USE tempdb;
GO

-- Create test table and index.
CREATE TABLE t_lock
    (
    c1 int, c2 int
    );
GO

CREATE INDEX t_lock_ci on t_lock(c1);
GO

-- Insert values into test table
INSERT INTO t_lock VALUES (1, 1);
INSERT INTO t_lock VALUES (2,2);
INSERT INTO t_lock VALUES (3,3);
INSERT INTO t_lock VALUES (4,4);
INSERT INTO t_lock VALUES (5,5);
INSERT INTO t_lock VALUES (6,6);
GO

-- Session 1
SET TRANSACTION ISOLATION LEVEL READ COMMITTED;

BEGIN TRAN
    SELECT c1
        FROM t_lock
        WITH(holdlock, rowlock);

-- Session 2
BEGIN TRAN
    UPDATE t_lock SET c1 = 10

The following query will display lock information. The value for <dbid> should be replaced with the database_id from sys.databases.

SELECT resource_type, resource_associated_entity_id,
    request_status, request_mode,request_session_id,
    resource_description 
    FROM sys.dm_tran_locks
    WHERE resource_database_id = <dbid>

The following query returns object information by using resource_associated_entity_id from the previous query. This query must be executed while you are connected to the database that contains the object.

SELECT object_name(object_id), *
    FROM sys.partitions
    WHERE hobt_id=<resource_associated_entity_id>

The following query will show blocking information.

SELECT 
        t1.resource_type,
        t1.resource_database_id,
        t1.resource_associated_entity_id,
        t1.request_mode,
        t1.request_session_id,
        t2.blocking_session_id
    FROM sys.dm_tran_locks as t1
    INNER JOIN sys.dm_os_waiting_tasks as t2
        ON t1.lock_owner_address = t2.resource_address;

Release the resources by rolling back the transactions.

-- Session 1
ROLLBACK;
GO

-- Session 2
ROLLBACK;
GO

B. Linking session information to operating system threads

The following example returns information that associates a session ID with a Windows thread ID. The performance of the thread can be monitored in the Windows Performance Monitor. This query does not return session IDs that are currently sleeping.

SELECT STasks.session_id, SThreads.os_thread_id
    FROM sys.dm_os_tasks AS STasks
    INNER JOIN sys.dm_os_threads AS SThreads
        ON STasks.worker_address = SThreads.worker_address
    WHERE STasks.session_id IS NOT NULL
    ORDER BY STasks.session_id;
GO

See Also

Reference

sys.dm_tran_database_transactions
Dynamic Management Views and Functions
Transaction Related Dynamic Management Views and Functions

Help and Information

Getting SQL Server 2005 Assistance