Skip to content

Latest commit

 

History

History
93 lines (68 loc) · 5.14 KB

sys-dm-tran-top-version-generators-transact-sql.md

File metadata and controls

93 lines (68 loc) · 5.14 KB
title description author ms.author ms.date ms.service ms.subservice ms.topic f1_keywords helpviewer_keywords dev_langs monikerRange
sys.dm_tran_top_version_generators (Transact-SQL)
sys.dm_tran_top_version_generators (Transact-SQL)
rwestMSFT
randolphwest
06/19/2023
sql
system-objects
reference
dm_tran_top_version_generators
sys.dm_tran_top_version_generators
dm_tran_top_version_generators_TSQL
sys.dm_tran_top_version_generators_TSQL
sys.dm_tran_top_version_generators 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_top_version_generators (Transact-SQL)

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

Returns a virtual table for the objects that are producing the most versions in the version store. sys.dm_tran_top_version_generators returns the top 256 aggregated record lengths that are grouped by the database_id and rowset_id. sys.dm_tran_top_version_generators retrieves data by querying the dm_tran_version_store virtual table. sys.dm_tran_top_version_generators is an inefficient view to run because this view queries the version store, and the version store can be very large. We recommend that you use this function to find the largest consumers of the version store.

Note

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

Syntax

  
sys.dm_tran_top_version_generators  

Table Returned

Column name Data type Description
database_id int Database ID.

In [!INCLUDE ssazure-sqldb], the values are unique within a single database or an elastic pool, but not within a logical server.
rowset_id bigint Rowset ID.
aggregated_record_length_in_bytes int Sum of the record lengths for each database_id and rowset_id pair in the version store.
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

Because sys.dm_tran_top_version_generators might have to read many pages as it scans the entire version store, running sys.dm_tran_top_version_generators can interfere with system performance.

Examples

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.

SELECT  
    database_id,  
    rowset_id,  
    aggregated_record_length_in_bytes  
  FROM sys.dm_tran_top_version_generators;  

[!INCLUDEssResult]

database_id rowset_id            aggregated_record_length_in_bytes  
----------- -------------------- ---------------------------------  
9           72057594038321152    87  
9           72057594038386688    33  

The output shows that all versions are created by database_id``9 and that the versions generate from two tables.

See also

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