question

Matt Whitfield avatar image
Matt Whitfield asked

How do I determine what filegroup my partition data is stored in?

Seeder question: I have a table whose clustered index is created on a partition scheme - how do I determine what file group each partition is stored in using a query? It needs to be a query rather than referencing the DDL because the information is needed for a space report.

t-sqlpartitioningstorage
10 |1200

Up to 2 attachments (including images) can be used with a maximum of 512.0 KiB each and 1.0 MiB total.

1 Answer

·
Tom Staab avatar image
Tom Staab answered

This turned out to be tougher than I thought it would. I had to do some serious BOL research to figure out the connection (sys.allocation_units). I decided to include the approximate number of rows from sys.partitions as some extra information.

DECLARE @TableName sysname = 'MyTable';

SELECT p.partition_number, fg.name, p.rows
FROM sys.partitions p
    INNER JOIN sys.allocation_units au
    ON au.container_id = p.hobt_id
    INNER JOIN sys.filegroups fg
    ON fg.data_space_id = au.data_space_id
WHERE p.object_id = OBJECT_ID(@TableName)
10 |1200

Up to 2 attachments (including images) can be used with a maximum of 512.0 KiB each and 1.0 MiB total.

Write an Answer

Hint: Notify or tag a user in this post by typing @username.

Up to 2 attachments (including images) can be used with a maximum of 512.0 KiB each and 1.0 MiB total.