Skip to content

Latest commit

 

History

History
60 lines (48 loc) · 4.59 KB

sys-dm-tran-session-transactions-transact-sql.md

File metadata and controls

60 lines (48 loc) · 4.59 KB
title description author ms.author ms.date ms.service ms.subservice ms.topic f1_keywords helpviewer_keywords dev_langs monikerRange
sys.dm_tran_session_transactions (Transact-SQL)
sys.dm_tran_session_transactions returns correlation information for associated transactions and sessions.
rwestMSFT
randolphwest
08/10/2023
sql
system-objects
reference
dm_tran_session_transactions
sys.dm_tran_session_transactions
sys.dm_tran_session_transactions_TSQL
dm_tran_session_transactions_TSQL
sys.dm_tran_session_transactions dynamic management view
TSQL
>=aps-pdw-2016||=azuresqldb-current||=azure-sqldw-latest||>=sql-server-2016||>=sql-server-linux-2017||=azuresqldb-mi-current

sys.dm_tran_session_transactions (Transact-SQL)

[!INCLUDE sql-asdb-asdbmi-asa-pdw]

Returns correlation information for associated transactions and sessions.

Note

To call this from [!INCLUDEssazuresynapse-md] or [!INCLUDEssPDW], use the name sys.dm_pdw_nodes_tran_session_transactions. [!INCLUDEsynapse-analytics-od-unsupported-syntax]

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 [!INCLUDEssNoVersion] 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: [!INCLUDEssazuresynapse-md], [!INCLUDEssPDW]

The identifier for the node that this distribution is on.

Permissions

On [!INCLUDEssNoVersion_md] 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.

Next steps