Skip to content

Instantly share code, notes, and snippets.

@stummsft
Created October 1, 2018 22:36
Show Gist options
  • Star 0 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save stummsft/ecb15c6596a0c21b9e9ba4dc49fa1828 to your computer and use it in GitHub Desktop.
Save stummsft/ecb15c6596a0c21b9e9ba4dc49fa1828 to your computer and use it in GitHub Desktop.
Which table is blocking a shrinkfile operation
/*
This script returns the further-allocated page per index per file in the database
This may be useful in reclaiming diskspace after a major data purge or migration operation
If a shrinkfile operation is not proceeding in a timely fashion or is being blocked,
this will help you target specific indexes to be rebuilt or migrated to a different filegroup
to help the space reclamation proceed.
*/
DECLARE
@tablename SYSNAME = NULL --Replace this if you only want to analyze a single table
, @indexname SYSNAME = NULL --Replace this if you only want to analyze a single index of a single table
, @result_limit INT = 200
;
-------------------------------------
DECLARE @tableid INT;
DECLARE @indexid INT;
SET @tableid = OBJECT_ID(@tablename)
SET @indexid = (
SELECT i.index_id
FROM sys.indexes i
WHERE
i.object_id = @tableid
AND (
i.name = @indexname
OR (@indexname = '(Heap)' AND i.name IS NULL)
)
)
SELECT
TOP (@result_limit)
s.name AS [Schema]
, COALESCE(t.name, '(System Table)') AS [Table]
, COALESCE(i.name, '(Heap)') AS [Index]
, df.name AS [File]
, MAX(pg.allocated_page_page_id) AS [PageID]
, MAX(pg.allocated_page_page_id) / 125 AS [Offset(MB)]
FROM sys.dm_db_database_page_allocations (DB_ID(), @tableid, @indexid, NULL, NULL) pg
--INNER JOIN sys.partitions p
-- ON pg.partition_id = p.partition_number
-- AND pg.index_id = p.index_id
-- AND pg.object_id = p.object_id
INNER JOIN sys.indexes i
ON pg.index_id = i.index_id
AND pg.object_id = i.object_id
LEFT JOIN sys.tables t
ON pg.object_id = t.object_id
LEFT JOIN sys.schemas s
ON t.schema_id = s.schema_id
INNER JOIN sys.database_files df
ON pg.allocated_page_file_id = df.file_id
GROUP BY
s.name, t.name, i.name, df.name
ORDER BY
--pg.allocated_page_file_id ASC, pg.allocated_page_page_id DESC
[File] ASC, [Offset(MB)] DESC
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment