sys.partitions (Transact-SQL)
Applies to:
SQL Server
Azure SQL Database
Azure SQL Managed Instance
Azure Synapse Analytics
Analytics Platform System (PDW)
SQL Endpoint in Microsoft Fabric
Warehouse in Microsoft Fabric
Contains a row for each partition of all the tables and most types of indexes in the database. Special index types such as Full-Text, Spatial, and XML are not included in this view. All tables and indexes in SQL Server contain at least one partition, whether or not they are explicitly partitioned.
Column name | Data type | Description |
---|---|---|
partition_id | bigint | Indicates the partition ID. Is unique within a database. |
object_id | int | Indicates the ID of the object to which this partition belongs. Every table or view is composed of at least one partition. |
index_id | int | Indicates the ID of the index within the object to which this partition belongs. 0 = heap 1 = clustered index 2 or greater = nonclustered index |
partition_number | int | Is a 1-based partition number within the owning index or heap. For non-partitioned tables and indexes, the value of this column is 1. |
hobt_id | bigint | Indicates the ID of the data heap or B-tree (HoBT) that contains the rows for this partition. |
rows | bigint | Indicates the approximate number of rows in this partition. |
filestream_filegroup_id | smallint | Applies to: SQL Server 2012 (11.x) and later. Indicates the ID of the FILESTREAM filegroup stored on this partition. |
data_compression | tinyint | Indicates the state of compression for each partition: 0 = NONE 1 = ROW 2 = PAGE 3 = COLUMNSTORE : Applies to: SQL Server 2012 (11.x) and later 4 = COLUMNSTORE_ARCHIVE : Applies to: SQL Server 2014 (12.x) and later Note: Full text indexes will be compressed in any edition of SQL Server. |
data_compression_desc | nvarchar(60) | Indicates the state of compression for each partition. Possible values for rowstore tables are NONE, ROW, and PAGE. Possible values for columnstore tables are COLUMNSTORE and COLUMNSTORE_ARCHIVE. |
Permissions
Requires membership in the public role. For more information, see Metadata Visibility Configuration.
Examples
Determine space used by object and show related partition information
The following query returns all the object in a database, the amount of space used in each object, and partition information related to each object.
SELECT object_name(object_id) AS ObjectName,
total_pages / 128. AS SpaceUsed_MB,
p.partition_id,
p.object_id,
p.index_id,
p.partition_number,
p.rows,
p.data_compression_desc
FROM sys.partitions AS p
JOIN sys.allocation_units AS au ON p.partition_id = au.container_id
ORDER BY SpaceUsed_MB DESC;
See Also
Object Catalog Views (Transact-SQL)
Catalog Views (Transact-SQL)
Querying the SQL Server System Catalog FAQ