sys.dm_db_file_space_usage (Transact-SQL)

Applies to: SQL Server Azure SQL Database Azure SQL Managed Instance Azure Synapse Analytics Analytics Platform System (PDW)

Returns space usage information for each data file in the database.

Note

To call this from Azure Synapse Analytics or Analytics Platform System (PDW), use the name sys.dm_pdw_nodes_db_file_space_usage. This syntax is not supported by serverless SQL pool in Azure Synapse Analytics.

Column name Data type Description
database_id smallint Database ID.

In Azure SQL Database, the values are unique within a single database or an elastic pool, but not within a logical server.
file_id smallint File ID.

file_id maps to file_id in sys.dm_io_virtual_file_stats and to fileid in sys.sysfiles.
filegroup_id smallint Applies to: SQL Server 2012 (11.x) and later versions.

Filegroup ID.
total_page_count bigint Applies to: SQL Server 2012 (11.x) and later versions.

Total number of pages in the data file.
allocated_extent_page_count bigint Applies to: SQL Server 2012 (11.x) and later versions.

Total number of pages in the allocated extents in the data file.
unallocated_extent_page_count bigint Total number of pages in the unallocated extents in the data file.

Unused pages in allocated extents aren't included.
version_store_reserved_page_count bigint Total number of pages in the uniform extents allocated for the version store. Version store pages are never allocated from mixed extents.

IAM pages aren't included, because they are always allocated from mixed extents. PFS pages are included if they are allocated from a uniform extent.

For more information, see sys.dm_tran_version_store (Transact-SQL).
user_object_reserved_page_count bigint Total number of pages allocated from uniform extents for user objects in the database. Unused pages from an allocated extent are included in the count.

IAM pages aren't included, because they are always allocated from mixed extents. PFS pages are included if they are allocated from a uniform extent.

You can use the total_pages column in the sys.allocation_units catalog view to return the reserved page count of each allocation unit in the user object. However, the total_pages column includes IAM pages.
internal_object_reserved_page_count bigint Total number of pages in uniform extents allocated for internal objects in the file. Unused pages from an allocated extent are included in the count.

IAM pages aren't included, because they are always allocated from mixed extents. PFS pages are included if they are allocated from a uniform extent.

There is no catalog view or dynamic management object that returns the page count of each internal object.
mixed_extent_page_count bigint Total number of allocated and unallocated pages in allocated mixed extents in the file. Mixed extents contain pages allocated to different objects. This count does include all the IAM pages in the file.
modified_extent_page_count bigint Applies to: SQL Server 2016 (13.x) SP2 and later versions.

Total number of pages modified in allocated extents of the file since last full database backup. The modified page count can be used to track the number of differential changes in the database since last full backup, to decide if differential backup is needed.
pdw_node_id int Applies to: Azure Synapse Analytics, Analytics Platform System (PDW)

The identifier for the node that this distribution is on.
distribution_id int Applies to: Azure Synapse Analytics, Analytics Platform System (PDW)

The unique numeric ID associated with the distribution.

Remarks

Page counts are always at the extent level. Therefore, page count values are always a multiple of eight. The extents that contain Global Allocation Map (GAM) and Shared Global Allocation Map (SGAM) allocation pages are allocated uniform extents. They aren't included in the previously described page counts. For more information about pages and extents, see Pages and Extents Architecture Guide.

The content of the current version store is in sys.dm_tran_version_store. Version store pages are tracked at the file level instead of the session and task level, because they are global resources. A session may generate versions, but the versions can't be removed when the session ends. Version store cleanup must consider the longest running transaction that needs access to the particular version. The longest running transaction related to version store clean-up can be discovered by viewing the elapsed_time_seconds column in sys.dm_tran_active_snapshot_database_transactions.

Frequent changes in the mixed_extent_page_count column may indicate heavy use of SGAM pages. When this occurs, you may see many PAGELATCH_UP waits in which the wait resource is an SGAM page. For more information, see sys.dm_os_waiting_tasks (Transact-SQL), sys.dm_os_wait_stats (Transact-SQL), and sys.dm_os_latch_stats (Transact-SQL).

User objects

The following objects are included in the user object page counters:

  • User-defined tables and indexes
  • System tables and indexes
  • Global temporary tables and indexes
  • Local temporary tables and indexes
  • Table variables
  • Tables returned in the table-valued functions

Internal objects

Internal objects are only in tempdb. The following objects are included in the internal object page counters:

  • Work tables for cursor or spool operations and temporary large object (LOB) storage
  • Work files for operations such as a hash join
  • Sort runs

Relationship cardinalities

From To Relationship
sys.dm_db_file_space_usage.database_id, file_id sys.dm_io_virtual_file_stats.database_id, file_id One-to-one

Permissions

On SQL Server 2019 (15.x) and earlier versions, and SQL Managed Instance, requires VIEW SERVER STATE permission.

On SQL Server 2022 (16.x) and later versions, requires VIEW SERVER PERFORMANCE STATE permission on the server.

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.

Examples

Determine the amount of free space in tempdb

The following query returns the total number of free pages and total free space in megabytes (MB) available in all data files in tempdb.

USE tempdb;
GO

SELECT
    SUM(unallocated_extent_page_count) AS [free pages],
    (SUM(unallocated_extent_page_count) * 1.0 / 128) AS [free space in MB]
FROM sys.dm_db_file_space_usage;

Determine the amount of space used by user objects

The following query returns the total number of pages used by user objects and the total space used by user objects in tempdb.

USE tempdb;
GO

SELECT
    SUM(user_object_reserved_page_count) AS [user object pages used],
    (SUM(user_object_reserved_page_count) * 1.0 / 128) AS [user object space in MB]
FROM sys.dm_db_file_space_usage;

See also