sys.dm_db_session_space_usage (Transact-SQL)


Updated: November 16, 2015

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

Returns the number of pages allocated and deallocated by each session for the database.

System_CAPS_ICON_note.jpg Note

This view is applicable only to the tempdb 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_session_space_usage.

Column nameData typeDescription
session_idsmallintSession ID.

 session_id maps to session_id in sys.dm_exec_sessions.
database_idsmallintDatabase ID.
user_objects_alloc_page_countbigintNumber of pages reserved or allocated for user objects by this session.
user_objects_dealloc_page_countbigintNumber of pages deallocated and no longer reserved for user objects by this session.
internal_objects_alloc_page_countbigintNumber of pages reserved or allocated for internal objects by this session.
internal_objects_dealloc_page_countbigintNumber of pages deallocated and no longer reserved for internal objects by this session.
user_objects_deferred_dealloc_page_countbigintNumber of pages which have been marked for deferred deallocation.

 Note: Introduced in service packs for SQL Server 2012 and SQL Server 2014.
pdw_node_idintApplies to: Azure SQL Data Warehouse, Parallel Data Warehouse

The identifier for the node that this distribution is on.

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.

IAM pages are not included in any of the allocation or deallocation counts reported by this view.

Page counters are initialized to zero (0) at the start of a session. The counters track the total number of pages that have been allocated or deallocated for tasks that are already completed in the session. The counters are updated only when a task ends; they do not reflect running tasks.

A session can have multiple requests active at the same time. A request can start multiple threads, tasks, if it is a parallel query.

For more information about the sessions, requests, and tasks, see sys.dm_exec_sessions (Transact-SQL), sys.dm_exec_requests (Transact-SQL), and sys.dm_os_tasks (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

Physical joins for sys.dm_db_session_space_usage


Dynamic Management Views and Functions (Transact-SQL)
Database Related Dynamic Management Views (Transact-SQL)
sys.dm_exec_sessions (Transact-SQL)
sys.dm_exec_requests (Transact-SQL)
sys.dm_os_tasks (Transact-SQL)
sys.dm_db_task_space_usage (Transact-SQL)
sys.dm_db_file_space_usage (Transact-SQL)

Community Additions