Today, I got asked by one of my DBA’s about a recently deployed database that seemed to have a lot of filegroups with only a few tables. He wanted to verify that one of the tables was correctly partition-aligned, as well as learn where all of the indexes for these tables were stored. After a quick search of the Internets, I was able to fashion the following script to help. The script below will find every index on every user table in a database, and then determine if it’s partitioned or not. If it’s partitioned, the scheme name is returned; if not, the filegroup name. The final column provides an XML list of filegroups (because schemes can span multiple filegroups) and file locations (because filegroups can span multiple files).
WITH C AS ( SELECT ps.data_space_id , f.name , d.physical_name FROM sys.filegroups f JOIN sys.database_files d ON d.data_space_id = f.data_space_id JOIN sys.destination_data_spaces dds ON dds.data_space_id = f.data_space_id JOIN sys.partition_schemes ps ON ps.data_space_id = dds.partition_scheme_id UNION SELECT f.data_space_id , f.name , d.physical_name FROM sys.filegroups f JOIN sys.database_files d ON d.data_space_id = f.data_space_id ) SELECT [ObjectName] = OBJECT_NAME(i.[object_id]) , [IndexID] = i.[index_id] , [IndexName] = i.[name] , [IndexType] = i.[type_desc] , [Partitioned] = CASE WHEN ps.data_space_id IS NULL THEN 'No' ELSE 'Yes' END , [StorageName] = ISNULL(ps.name, f.name) , [FileGroupPaths] = CAST(( SELECT name AS "FileGroup" , physical_name AS "DatabaseFile" FROM C WHERE i.data_space_id = c.data_space_id FOR XML PATH('') ) AS XML) FROM [sys].[indexes] i LEFT JOIN sys.partition_schemes ps ON ps.data_space_id = i.data_space_id LEFT JOIN sys.filegroups f ON f.data_space_id = i.data_space_id WHERE OBJECTPROPERTY(i.[object_id], 'IsUserTable') = 1 ORDER BY [ObjectName], [IndexName]