Index Fragmentation Status (includes Partitioned Tables/Indexes)

  • Comments posted to this topic are about the item Index Fragmentation Status (includes Partitioned Tables/Indexes)

  • It gives me the error

    Msg 102, Level 15, State 1, Line 31

    Incorrect syntax near '('.

    I understand that is on the:

    sys.dm_db_index_physical_stats (DB_ID()

    But no matter what parameter I pass to the DB_ID function it gives me an error.

  • Only tested on sql 2005 & 2008, so that may be an issue.

    The DBID() function with no argument returns the database id for the current db.

    The script should be run as is, without adding your database name.

    I accidently pasted the '- Hide quoted text -' comment at the top, make sure you've removed that too.

  • I just found out that that it works on another DB on the same server (sql 2005) but not in the first one I tried...

  • I was having the same issue with DBs on a SQL Server 2005 instance - but the DBs had been imported from an older instance and set to Compatibility 80 - SQL 2000.

    Adding the DB name to the DB_ID funtion does not help.

    I can Select DB_ID() to get the ID number, and the code works if I use the actual number in place of the function.

    Thanks for the code, I've been wanting to check this for a while!

  • I like the script but found it to be slow. I have mad a slight change and it is much faster:

    ;WITH IndexStats AS

    (

    select

    object_id,

    index_id,

    partition_number,

    Avg_Fragmentation_In_Percent,

    Fragment_Count,

    Avg_Fragment_Size_In_Pages,

    Page_Count

    from

    sys.dm_db_index_physical_stats(DB_ID(), NULL, NULL , NULL, N'LIMITED')

    )

    SELECT

    SCHEMA_NAME(o.schema_id) AS SchemaName

    ,OBJECT_NAME(o.object_id) AS TableName

    ,i.name AS IndexName

    ,i.type_desc AS IndexType

    ,CASE WHEN ISNULL(ps.function_id,1) = 1 THEN 'NO' ELSE 'YES' END AS Partitioned

    ,COALESCE(fg.name ,fgp.name) AS FileGroupName

    ,p.partition_number AS PartitionNumber

    ,p.rows AS PartitionRows

    ,dmv.Avg_Fragmentation_In_Percent

    ,dmv.Fragment_Count

    ,dmv.Avg_Fragment_Size_In_Pages

    ,dmv.Page_Count

    ,prv_left.value AS PartitionLowerBoundaryValue

    ,prv_right.value AS PartitionUpperBoundaryValue

    ,CASE WHEN pf.boundary_value_on_right = 1 THEN 'RIGHT' WHEN pf.boundary_value_on_right = 0 THEN 'LEFT' ELSE 'NONE' END AS PartitionRange

    ,pf.name AS PartitionFunction

    ,ds.name AS PartitionScheme

    FROM sys.partitions AS p WITH (NOLOCK)

    INNER JOIN sys.indexes AS i WITH (NOLOCK)

    ON i.object_id = p.object_id

    AND i.index_id = p.index_id

    INNER JOIN sys.objects AS o WITH (NOLOCK)

    ON o.object_id = i.object_id

    INNER JOIN IndexStats dmv

    ON dmv.OBJECT_ID = i.object_id

    AND dmv.index_id = i.index_id

    AND dmv.partition_number = p.partition_number

    LEFT JOIN sys.data_spaces AS ds WITH (NOLOCK)

    ON ds.data_space_id = i.data_space_id

    LEFT JOIN sys.partition_schemes AS ps WITH (NOLOCK)

    ON ps.data_space_id = ds.data_space_id

    LEFT JOIN sys.partition_functions AS pf WITH (NOLOCK)

    ON pf.function_id = ps.function_id

    LEFT JOIN sys.destination_data_spaces AS dds WITH (NOLOCK)

    ON dds.partition_scheme_id = ps.data_space_id

    AND dds.destination_id = p.partition_number

    LEFT JOIN sys.filegroups AS fg WITH (NOLOCK)

    ON fg.data_space_id = i.data_space_id

    LEFT JOIN sys.filegroups AS fgp WITH (NOLOCK)

    ON fgp.data_space_id = dds.data_space_id

    LEFT JOIN sys.partition_range_values AS prv_left WITH (NOLOCK)

    ON ps.function_id = prv_left.function_id

    AND prv_left.boundary_id = p.partition_number - 1

    LEFT JOIN sys.partition_range_values AS prv_right WITH (NOLOCK)

    ON ps.function_id = prv_right.function_id

    AND prv_right.boundary_id = p.partition_number

    WHERE

    OBJECTPROPERTY(p.object_id, 'ISMSShipped') = 0

    ORDER BY

    SchemaName

    ,TableName

    ,IndexName

    ,PartitionNumber

    Using a CTE for the stats seems to be much better that joining directly to the function.

  • Cheers Ed, that's great. I guess it works better due to the function not exposing statistics to the query optimiser, but welcome you're take on what inspired you to change it.

    (Updating my scripts, thank you)

    r

  • Being quite old and used to managing resources, I am always looking for ways to make what I do faster, better and easier to use. When I tried to run the original, it ran forever before I killed it. I started out by pulling out pieces of the code, creating tables of the data needed to get the results. As left joins are very expensive, I first pulled the inner joined parts together to create a table. The Table was defined to include columns for all of the data that would later be needed. I then started coding updates to this table from the previously left joined tables. It was when I tried to used this process to update from the function that I realized where the issue was. I went back to the original and added the CTE and removed the join. I still think that my first method would decrease the time significantly by removing the left joins and replacing them all with updates. I just ran out of time to go that far.

  • Thanks for the script.

Viewing 9 posts - 1 through 8 (of 8 total)

You must be logged in to reply to this topic. Login to reply