sys.dm_db_stats_properties (Transact-SQL)
Applies to: SQL Server Azure SQL Database Azure SQL Managed Instance
Returns properties of statistics for the specified database object (table or indexed view) in the current SQL Server database. For partitioned tables, see the similar sys.dm_db_incremental_stats_properties.
sys.dm_db_stats_properties (object_id, stats_id)
object_id
Is the ID of the object in the current database for which properties of one of its statistics is requested. object_id is int.
stats_id
Is the ID of statistics for the specified object_id. The statistics ID can be obtained from the sys.stats dynamic management view. stats_id is int.
Column name | Data type | Description |
---|---|---|
object_id | int | ID of the object (table or indexed view) for which to return the properties of the statistics object. |
stats_id | int | ID of the statistics object. Is unique within the table or indexed view. For more information, see sys.stats (Transact-SQL). |
last_updated | datetime2 | Date and time the statistics object was last updated. For more information, see the Remarks section in this page. |
rows | bigint | Total number of rows in the table or indexed view when statistics were last updated. If the statistics are filtered or correspond to a filtered index, the number of rows might be less than the number of rows in the table. |
rows_sampled | bigint | Total number of rows sampled for statistics calculations. |
steps | int | Number of steps in the histogram. For more information, see DBCC SHOW_STATISTICS (Transact-SQL). |
unfiltered_rows | bigint | Total number of rows in the table before applying the filter expression (for filtered statistics). If statistics are not filtered, unfiltered_rows is equal to the value returns in the rows column. |
modification_counter | bigint | Total number of modifications for the leading statistics column (the column on which the histogram is built) since the last time statistics were updated. Memory-optimized tables: starting SQL Server 2016 (13.x) and in Azure SQL Database this column contains: total number of modifications for the table since the last time statistics were updated or the database was restarted. |
persisted_sample_percent | float | Persisted sample percentage used for statistic updates that do not explicitly specify a sampling percentage. If value is zero, then no persisted sample percentage is set for this statistic. Applies to: SQL Server 2016 (13.x) SP1 CU4 |
sys.dm_db_stats_properties returns an empty rowset under any of the following conditions:
- object_id or stats_id is NULL.
- The specified object is not found or does not correspond to a table or indexed view.
- The specified statistics ID does not correspond to existing statistics for the specified object ID.
- The current user does not have permissions to view the statistics object.
This behavior allows for the safe usage of sys.dm_db_stats_properties when cross applied to rows in views such as sys.objects and sys.stats.
Statistics update date is stored in the statistics blob object together with the histogram and density vector, not in the metadata. When no data is read to generate statistics data, the statistics blob is not created, the date is not available, and the last_updated column is NULL. This is the case for filtered statistics for which the predicate does not return any rows, or for new empty tables.
Requires that the user has select permissions on statistics columns or the user owns the table or the user is a member of the sysadmin
fixed server role, the db_owner
fixed database role, or the db_ddladmin
fixed database role.
The following example returns the statistics for the Person.Person
table in the AdventureWorks database.
SELECT * FROM sys.dm_db_stats_properties (object_id('Person.Person'), 1);
The following example returns properties of all statistics that exist for the table TEST.
SELECT sp.stats_id, name, filter_definition, last_updated, rows, rows_sampled, steps, unfiltered_rows, modification_counter
FROM sys.stats AS stat
CROSS APPLY sys.dm_db_stats_properties(stat.object_id, stat.stats_id) AS sp
WHERE stat.object_id = object_id('TEST');
The following example returns all tables, indexed views, and statistics in the current database for which the leading column was modified more than 1000 times since the last statistics update.
SELECT obj.name, obj.object_id, stat.name, stat.stats_id, last_updated, modification_counter
FROM sys.objects AS obj
INNER JOIN sys.stats AS stat ON stat.object_id = obj.object_id
CROSS APPLY sys.dm_db_stats_properties(stat.object_id, stat.stats_id) AS sp
WHERE modification_counter > 1000;
DBCC SHOW_STATISTICS (Transact-SQL)
sys.stats (Transact-SQL)
Object Related Dynamic Management Views and Functions (Transact-SQL)
Dynamic Management Views and Functions (Transact-SQL)
sys.dm_db_incremental_stats_properties (Transact-SQL)
sys.dm_db_stats_histogram (Transact-SQL)