Skip to content

Instantly share code, notes, and snippets.

@JustinMcNamara74
Last active August 29, 2015 14:17
Show Gist options
  • Save JustinMcNamara74/c31d629047e8fc806428 to your computer and use it in GitHub Desktop.
Save JustinMcNamara74/c31d629047e8fc806428 to your computer and use it in GitHub Desktop.
#MSSQL View table pagecount and fragmentation levels.
-- Avg Fragmentation Percentages
DECLARE @DatabaseID int
SET @DatabaseID = DB_ID()
SELECT DB_NAME(@DatabaseID) AS DatabaseName,
schemas.[name] AS SchemaName,
objects.[name] AS ObjectName,
indexes.[name] AS IndexName,
objects.type_desc AS ObjectType,
indexes.type_desc AS IndexType,
dm_db_index_physical_stats.partition_number AS PartitionNumber,
dm_db_index_physical_stats.page_count AS [PageCount],
dm_db_index_physical_stats.avg_fragmentation_in_percent AS AvgFragmentationInPercent
FROM sys.dm_db_index_physical_stats (@DatabaseID, NULL, NULL, NULL, 'LIMITED') dm_db_index_physical_stats
INNER JOIN sys.indexes indexes ON dm_db_index_physical_stats.[object_id] = indexes.[object_id] AND dm_db_index_physical_stats.index_id = indexes.index_id
INNER JOIN sys.objects objects ON indexes.[object_id] = objects.[object_id]
INNER JOIN sys.schemas schemas ON objects.[schema_id] = schemas.[schema_id]
WHERE objects.[type] IN('U','V') --U=Table(user defined), V=View
AND objects.is_ms_shipped = 0
AND indexes.[type] IN(1,2,3,4) --1=Clustered, 2=Nonclustered, 3=XML, 4=Spatial
AND indexes.is_disabled = 0
AND indexes.is_hypothetical = 0
AND dm_db_index_physical_stats.alloc_unit_type_desc = 'IN_ROW_DATA'
AND dm_db_index_physical_stats.index_level = 0
AND dm_db_index_physical_stats.page_count >= 1000
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment