sys.pdw_nodes_partitions (Transact-SQL)
Applies to: Azure Synapse Analytics Analytics Platform System (PDW)
Contains a row for each partition of all the tables, and most types of indexes in a Azure Synapse Analytics database. All tables and indexes contain at least one partition, whether or not they are explicitly partitioned.
Column name | Data type | Description |
---|---|---|
partition_id | bigint | ID of the partition. Is unique within a database. |
object_id | int | ID of the object to which this partition belongs. Every table or view is composed of at least one partition. |
index_id | int | ID of the index within the object to which this partition belongs. |
partition_number | int | 1-based partition number within the owning index or heap. For Azure Synapse Analytics, the value of this column is 1. |
hobt_id | bigint | ID of the data heap or B-tree (HoBT) that contains the rows for this partition. |
rows | bigint | Approximate number of rows in this partition. |
data_compression | int | Indicates the state of compression for each partition: 0 = NONE 1 = ROW 2 = PAGE 3 = COLUMNSTORE |
data_compression_desc | nvarchar(60) | Indicates the state of compression for each partition. Possible values are NONE, ROW, and PAGE. |
pdw_node_id | int | Unique identifier of a Azure Synapse Analytics node. |
Permissions
Requires CONTROL SERVER
permission.
Examples: Azure Synapse Analytics and Analytics Platform System (PDW)
Example A: Display rows in each partition within each distribution
Applies to: Azure Synapse Analytics, Analytics Platform System (PDW)
To display the number of rows in each partition within each distribution, use DBCC PDW_SHOWPARTITIONSTATS (SQL Server PDW) .
Example B: Uses system views to view rows in each partition of each distribution of a table
Applies to: Azure Synapse Analytics
This query returns the number of rows in each partition of each distribution of the table myTable
.
SELECT o.name, pnp.index_id, pnp.partition_id, pnp.rows,
pnp.data_compression_desc, pnp.pdw_node_id
FROM sys.pdw_nodes_partitions AS pnp
JOIN sys.pdw_nodes_tables AS NTables
ON pnp.object_id = NTables.object_id
AND pnp.pdw_node_id = NTables.pdw_node_id
JOIN sys.pdw_table_mappings AS TMap
ON NTables.name = TMap.physical_name
AND substring(TMap.physical_name,40, 10) = pnp.distribution_id
JOIN sys.objects AS o
ON TMap.object_id = o.object_id
WHERE o.name = 'myTable'
ORDER BY o.name, pnp.index_id, pnp.partition_id;
See Also
Azure Synapse Analytics and Parallel Data Warehouse Catalog Views