sys.dm_tran_current_transaction (Transact-SQL)


THIS TOPIC APPLIES TO: yesSQL Server (starting with 2008)yesAzure SQL DatabaseyesAzure SQL Data Warehouse yesParallel Data Warehouse

Returns a single row that displays the state information of the transaction in the current session.

System_CAPS_ICON_note.jpg Note

To call this from Azure SQL Data Warehouse or Parallel Data Warehouse, use the name sys.dm_pdw_nodes_tran_current_transaction.


Column nameData typeDescription
transaction_idbigintTransaction ID of the current snapshot.
transaction_sequence_numbigintSequence number of the transaction that generates the record version.
transaction_is_snapshotbitSnapshot isolation state. This value is 1 if the transaction is started under snapshot isolation. Otherwise, the value is 0.
first_snapshot_sequence_numbigintLowest transaction sequence number of the transactions that were active when a snapshot was taken. On execution, a snapshot transaction takes a snapshot of all of the active transactions at that time. For nonsnapshot transactions, this column shows 0.
last_transaction_sequence_numbigintGlobal sequence number. This value represents the last transaction sequence number that was generated by the system.
first_useful_sequence_numbigintGlobal sequence number. This value represents the oldest transaction sequence number of the transaction that has row versions that must be retained in the version store. Row versions that were created by prior transactions can be removed.
pdw_node_idintApplies to: Azure SQL Data Warehouse, Parallel Data Warehouse

The identifier for the node that this distribution is on.

On SQL Server requires VIEW SERVER STATE permission on the server.

On SQL Database Premium Tiers requires the VIEW DATABASE STATE permission in the database. On SQL Database Standard and Basic Tiers requires the SQL Database admin account.

The following example uses a test scenario in which four concurrent transactions, each identified by a transaction sequence number (XSN), are running in a database that has the ALLOW_SNAPSHOT_ISOLATION and READ_COMMITTED_SNAPSHOT options set to ON. The following transactions are running:

  • XSN-57 is an update operation under serializable isolation.

  • XSN-58 is the same as XSN-57.

  • XSN-59 is a select operation under snapshot isolation.

  • XSN-60 is the same as XSN-59.

The following query is executed within the scope of each transaction.

  FROM sys.dm_tran_current_transaction;  

Here is the result for XSN-59.

transaction_id       transaction_sequence_num transaction_is_snapshot  
-------------------- ------------------------ -----------------------  
9387                 59                       1                         
first_snapshot_sequence_num last_transaction_sequence_num  
--------------------------- -----------------------------  
57                               61                        

The output shows that XSN-59 is a snapshot transaction that uses XSN-57 as the first transaction that was active when XSN-59 started. This means that XSN-59 reads data committed by transactions that have a transaction sequence number lower than XSN-57.

Here is the result for XSN-57.

transaction_id       transaction_sequence_num transaction_is_snapshot  
-------------------- ------------------------ -----------------------  
9295                 57                       0  
first_snapshot_sequence_num last_transaction_sequence_num  
--------------------------- -----------------------------  
NULL                        61  

Because XSN-57 is not a snapshot transaction, first_snapshot_sequence_num is NULL.

Dynamic Management Views and Functions (Transact-SQL)
Transaction Related Dynamic Management Views and Functions (Transact-SQL)

Community Additions