sys.dm_db_file_space_usage (Transact-SQL)

 

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

Returns space usage information for each file in the database.

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_db_file_space_usage.

Column nameData typeDescription
database_idsmallintDatabase ID.
file_idsmallintFile ID.

file_id maps to file_id in sys.dm_io_virtual_file_stats and to fileid in sys.sysfiles.
filegroup_idsmallintApplies to: SQL Server 2012 through SQL Server 2016.

Filegroup ID.
total_page_countbigintApplies to: SQL Server 2012 through SQL Server 2016.

Total number of pages in the file.
allocated_extent_page_countbigintApplies to: SQL Server 2012 through SQL Server 2016.

Total number of pages in the allocated extents in the file.
unallocated_extent_page_countbigintTotal number of pages in the unallocated extents in the file.

Unused pages in allocated extents are not included.
version_store_reserved_page_countbigintTotal number of pages in the uniform extents allocated for the version store. Version store pages are never allocated from mixed extents.

IAM pages are not 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_countbigintTotal 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 are not 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, note that the total_pages column includes IAM pages.
internal_object_reserved_page_countbigintTotal 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 are not 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_countbigintTotal 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.
pdw_node_idintApplies to: Azure SQL Data Warehouse, Parallel Data Warehouse

The identifier for the node that this distribution is on.
distribution_idintApplies to: Azure SQL Data Warehouse, Parallel Data Warehouse

The unique numeric id associated with the distribution.

Page counts are always at the extent level. Therefore, page count values will always be 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 are not included in the previously described page counts.

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 cannot 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).

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 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

FromToRelationship
sys.dm_db_file_space_usage.database_id, file_idsys.dm_io_virtual_file_stats.database_id, file_idOne-to-one

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.

Determing 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 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;  

Determining 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;  
  

Dynamic Management Views and Functions (Transact-SQL)
Database Related Dynamic Management Views (Transact-SQL)
sys.dm_db_task_space_usage (Transact-SQL)
sys.dm_db_session_space_usage (Transact-SQL)

Community Additions

ADD
Show: