sys.dm_tran_database_transactions (Transact-SQL)
Applies to: SQL Server (all supported versions)
Azure SQL Database
Azure SQL Managed Instance
Azure Synapse Analytics
Parallel Data Warehouse
Returns information about transactions at the database level.
Note
To call this DMV from Azure Synapse Analytics or Parallel Data Warehouse, use the name sys.dm_pdw_nodes_tran_database_transactions.
Column name | Data type | Description |
---|---|---|
transaction_id | bigint | ID of the transaction at the instance level, not the database level. It is only unique across all databases within an instance, but not unique across all server instances. |
database_id | int | ID of the database associated with the transaction. |
database_transaction_begin_time | datetime | Time at which the database became involved in the transaction. Specifically, it is the time of the first log record in the database for the transaction. |
database_transaction_type | int | 1 = Read/write transaction 2 = Read-only transaction 3 = System transaction |
database_transaction_state | int | 1 = The transaction has not been initialized. 3 = The transaction has been initialized but has not generated any log records. 4 = The transaction has generated log records. 5 = The transaction has been prepared. 10 = The transaction has been committed. 11 = The transaction has been rolled back. 12 = The transaction is being committed. (The log record is being generated, but has not been materialized or persisted.) |
database_transaction_status | int | Identified for informational purposes only. Not supported. Future compatibility is not guaranteed. |
database_transaction_status2 | int | Identified for informational purposes only. Not supported. Future compatibility is not guaranteed. |
database_transaction_log_record_count | bigint | Applies to: SQL Server 2008 and later. Number of log records generated in the database for the transaction. |
database_transaction_replicate_record_count | int | Applies to: SQL Server 2008 and later. Number of log records generated in the database for the transaction that is replicated. |
database_transaction_log_bytes_used | bigint | Applies to: SQL Server 2008 and later. Number of bytes used so far in the database log for the transaction. |
database_transaction_log_bytes_reserved | bigint | Applies to: SQL Server 2008 and later. Number of bytes reserved for use in the database log for the transaction. |
database_transaction_log_bytes_used_system | int | Applies to: SQL Server 2008 and later. Number of bytes used so far in the database log for system transactions on behalf of the transaction. |
database_transaction_log_bytes_reserved_system | int | Applies to: SQL Server 2008 and later. Number of bytes reserved for use in the database log for system transactions on behalf of the transaction. |
database_transaction_begin_lsn | numeric(25,0) | Applies to: SQL Server 2008 and later. Log sequence number (LSN) of the begin record for the transaction in the database log. |
database_transaction_last_lsn | numeric(25,0) | Applies to: SQL Server 2008 and later. LSN of the most recently logged record for the transaction in the database log. |
database_transaction_most_recent_savepoint_lsn | numeric(25,0) | Applies to: SQL Server 2008 and later. LSN of the most recent savepoint for the transaction in the database log. |
database_transaction_commit_lsn | numeric(25,0) | Applies to: SQL Server 2008 and later. LSN of the commit log record for the transaction in the database log. |
database_transaction_last_rollback_lsn | numeric(25,0) | Applies to: SQL Server 2008 and later. LSN that was most recently rolled back to. If no rollback has taken place, the value is MaxLSN. |
database_transaction_next_undo_lsn | numeric(25,0) | Applies to: SQL Server 2008 and later. LSN of the next record to undo. |
pdw_node_id | int | Applies to: Azure Synapse Analytics, Parallel Data Warehouse The identifier for the node that this distribution is on. |
Permissions
On SQL Server, requires VIEW SERVER STATE
permission.
On SQL Database Basic, S0, and S1 service objectives, and for databases in elastic pools, the server admin account or the Azure Active Directory admin account is required. On all other SQL Database service objectives, the VIEW DATABASE STATE
permission is required in the database.
See Also
sys.dm_tran_active_transactions (Transact-SQL)
sys.dm_tran_session_transactions (Transact-SQL)
Dynamic Management Views and Functions (Transact-SQL)
Transaction Related Dynamic Management Views and Functions (Transact-SQL)