Skip to content

Commit

Permalink
added filter by table, partition size, and various fixes
Browse files Browse the repository at this point in the history
  • Loading branch information
EitanBlumin committed Feb 5, 2024
1 parent 33898df commit 0b1a1c2
Showing 1 changed file with 27 additions and 10 deletions.
37 changes: 27 additions & 10 deletions Utility Scripts/Partitioning/Collect Partitioning Information.sql
Original file line number Diff line number Diff line change
@@ -1,6 +1,7 @@
DECLARE
@PartitionLevel bit = 1 -- optionally set to 1 to view details per partition number
, @FilterByPartitionFunction sysname = NULL -- optionally filter by a specific partition function name
, @FilterByTableName sysname = NULL -- optionally filter by a specific table name

SELECT DISTINCT
database_name = DB_NAME()
Expand All @@ -11,27 +12,43 @@ SELECT DISTINCT
, partition_scheme = ps.name
, column_type = tp.name
, params.max_length, params.precision, params.scale, params.collation_name
, table_schema_name = OBJECT_SCHEMA_NAME(c.object_id)
, table_name = OBJECT_NAME(c.object_id)
, table_schema_name = sc.name
, table_name = so.name
, index_name = ix.name
, column_name = c.name
, partition_number = CASE WHEN @PartitionLevel = 1 THEN ISNULL(rv.boundary_id, p.partition_number) END
, partition_range_value = CASE WHEN @PartitionLevel = 1 THEN rv.value END
, boundary_id = CASE WHEN @PartitionLevel = 1 THEN prv.boundary_id END
, partition_number = CASE WHEN @PartitionLevel = 1 THEN p.partition_number END
, partition_range_value = CASE WHEN @PartitionLevel = 1 THEN prv.value END
, [rows] = CASE WHEN @PartitionLevel = 1 THEN p.rows END
, [in_row_MB] = CASE WHEN @PartitionLevel = 1 THEN stat.in_row_reserved_page_count * 8./1024. END
, [LOB_MB] = CASE WHEN @PartitionLevel = 1 THEN stat.lob_reserved_page_count * 8./1024. END
, partition_filegroup = CASE WHEN @PartitionLevel = 1 THEN fg.name END
FROM sys.partition_schemes AS ps
INNER JOIN sys.partition_functions AS pf ON ps.function_id = pf.function_id
FROM sys.partition_functions AS pf
INNER JOIN sys.partition_parameters AS params ON params.function_id = pf.function_id
INNER JOIN sys.types AS tp ON params.system_type_id = tp.system_type_id AND params.user_type_id = tp.user_type_id
INNER JOIN sys.partition_schemes as ps on ps.function_id=pf.function_id
INNER JOIN sys.indexes as si on si.data_space_id=ps.data_space_id
INNER JOIN sys.objects as so on si.object_id = so.object_id
INNER JOIN sys.schemas as sc on so.schema_id = sc.schema_id
INNER JOIN sys.partitions as p on si.object_id=p.object_id and si.index_id=p.index_id
LEFT JOIN sys.indexes AS ix ON ix.data_space_id = ps.data_space_id
LEFT JOIN sys.partitions AS p ON p.object_id = ix.object_id AND p.index_id = ix.index_id
LEFT JOIN sys.index_columns AS ic ON ic.object_id = p.object_id AND ic.index_id = p.index_id AND ic.partition_ordinal > 0
LEFT JOIN sys.columns AS c ON c.object_id = p.object_id AND c.column_id = ic.column_id
LEFT JOIN sys.partition_range_values AS rv ON rv.function_id = pf.function_id AND rv.boundary_id = p.partition_number
LEFT JOIN sys.destination_data_spaces dds ON rv.boundary_id = dds.destination_id AND ps.data_space_id = dds.partition_scheme_id
LEFT JOIN sys.filegroups AS fg ON dds.data_space_id = fg.data_space_id
LEFT JOIN sys.partition_range_values as prv on prv.function_id=pf.function_id AND p.partition_number=
CASE pf.boundary_value_on_right WHEN 1
THEN prv.boundary_id + 1
ELSE prv.boundary_id
END
/* For left-based functions, partition_number = boundary_id,
for right-based functions we need to add 1 */
INNER JOIN sys.dm_db_partition_stats as stat on stat.object_id=p.object_id AND stat.index_id=p.index_id AND stat.index_id=p.index_id and stat.partition_id=p.partition_id AND stat.partition_number=p.partition_number
INNER JOIN sys.allocation_units as au on au.container_id = p.hobt_id AND au.type_desc ='IN_ROW_DATA'
/* Avoiding double rows for columnstore indexes. */
/* We can pick up LOB page count from partition_stats */
INNER JOIN sys.filegroups as fg on fg.data_space_id = au.data_space_id
WHERE
(@FilterByPartitionFunction IS NULL OR pf.name = @FilterByPartitionFunction)
AND (@FilterByTableName IS NULL OR OBJECT_ID(@FilterByTableName) = so.object_id)
ORDER BY
partition_function, partition_scheme, table_schema_name, table_name, index_name, partition_number
OPTION(RECOMPILE)

0 comments on commit 0b1a1c2

Please sign in to comment.