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.

more ▼

asked Oct 27, 2009 at 06:57 PM in Default

avatar image

Matt Whitfield ♦♦
29.5k 62 66 88

(comments are locked)
10|1200 characters needed characters left

1 answer: sort voted first

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)

more ▼

answered Oct 28, 2009 at 12:12 AM

avatar image

Tom Staab ♦
14.5k 7 14 18

(comments are locked)
10|1200 characters needed characters left
Your answer
toggle preview:

Up to 2 attachments (including images) can be used with a maximum of 524.3 kB each and 1.0 MB total.

Follow this question

By Email:

Once you sign in you will be able to subscribe for any updates here



Answers and Comments

SQL Server Central

Need long-form SQL discussion? SQLserverCentral.com is the place.



asked: Oct 27, 2009 at 06:57 PM

Seen: 12725 times

Last Updated: Oct 27, 2009 at 06:57 PM

Copyright 2016 Redgate Software. Privacy Policy