sys.dm_tran_session_transactions (Transact-SQL)
Applies to: SQL Server Azure SQL Database Azure SQL Managed Instance Azure Synapse Analytics Analytics Platform System (PDW)
Returns correlation information for associated transactions and sessions.
Note
To call this from Azure Synapse Analytics or Analytics Platform System (PDW), use the name sys.dm_pdw_nodes_tran_session_transactions
. This syntax is not supported by serverless SQL pool in Azure Synapse Analytics.
Column name | Data type | Description |
---|---|---|
session_id | int | ID of the session under which the transaction is running. |
transaction_id | bigint | ID of the transaction. |
transaction_descriptor | binary(8) | Transaction identifier used by SQL Server when communicating with the client driver. |
enlist_count | int | Number of active requests in the session working on the transaction. |
is_user_transaction | bit | 1 = The transaction was initiated by a user request. 0 = System transaction. |
is_local | bit | 1 = Local transaction. 0 = Distributed transaction or an enlisted bound session transaction. |
is_enlisted | bit | 1 = Enlisted distributed transaction. 0 = Not an enlisted distributed transaction. |
is_bound | bit | 1 = The transaction is active on the session via bound sessions. 0 = The transaction is not active on the session via bound sessions. |
open_transaction_count | int | The number of open transactions for each session. |
pdw_node_id | int | Applies to: Azure Synapse Analytics, Analytics Platform System (PDW) The identifier for the node that this distribution is on. |
Permissions
On SQL Server and SQL Managed Instance, requires VIEW SERVER STATE
permission.
On SQL Database Basic, S0, and S1 service objectives, and for databases in elastic pools, the server admin account, the Microsoft Entra admin account, or membership in the ##MS_ServerStateReader##
server role is required. On all other SQL Database service objectives, either the VIEW DATABASE STATE
permission on the database, or membership in the ##MS_ServerStateReader##
server role is required.
Permissions for SQL Server 2022 and later
Requires VIEW SERVER PERFORMANCE STATE permission on the server.
Remarks
Through bound sessions and distributed transactions, it is possible for a transaction to be running under more than one session. In such cases, sys.dm_tran_session_transactions
shows multiple rows for the same transaction_id
, one for each session under which the transaction is running. Because of differences in how they are recorded, open_transaction_count
may not match sys.dm_exec_sessions
.open_transaction_count
.
By executing multiple requests in autocommit mode using multiple active result sets (MARS), it is possible to have more than one active transaction on a single session. In such cases, sys.dm_tran_session_transactions
shows multiple rows for the same session_id
, one for each transaction running under that session.