Home Forums SQL Server 2005 Administering Best Index Rebuild/Reorganize and Update Statistics Strategy RE: Best Index Rebuild/Reorganize and Update Statistics Strategy

  • george sibbald (7/18/2013)


    SQL_Surfer (7/17/2013)


    Thank you so much for your suggestion. How about is there a way to figure out which stats are mostly used and needs updated?

    Another question...For two 150 GB database.....both of their ldf files are in the same folder...So, is it recommended to do maintenace one by one or we could do in parallel....I am kind of worried about doing parallel as that could fill up the log and more use of tempdb.

    Another question...Is setting up Auto Update Statistics to true is a good practise? Then that way, we don't need to do maintenance on statistics?

    The folder that holds the log files should be large enough to accommodate both at their maximum, you don't want to be continually shrinking them. Having said that reindex the databases consecutively if you can to reduce load.

    It is best practice to leave auto update stats on. there are edge cases where stats can get updated at busy times when the server is under load.

    Look for indexes that are heavily used, those are the ones whose stats are most likely need updating. the main case is an ever increasing clustered index, as only one row is added at a time its not enough to trigger an auto update stats but there is (recent and probably important) data in the table SQL has no metadata on. Use this query

    -- Index Read/Write stats for a single table

    SELECT OBJECT_NAME(s.[object_id]) AS [TableName],

    i.name AS [IndexName], i.index_id,

    SUM(user_seeks) AS [User Seeks], SUM(user_scans) AS [User Scans],

    SUM(user_lookups)AS [User Lookups],

    SUM(user_seeks + user_scans + user_lookups)AS [Total Reads],

    SUM(user_updates) AS [Total Writes]

    FROM sys.dm_db_index_usage_stats AS s

    INNER JOIN sys.indexes AS i

    ON s.[object_id] = i.[object_id]

    AND i.index_id = s.index_id

    WHERE OBJECTPROPERTY(s.[object_id],'IsUserTable') = 1

    AND s.database_id = DB_ID()

    AND OBJECT_NAME(s.[object_id]) = N'tablename'

    GROUP BY OBJECT_NAME(s.[object_id]), i.name, i.index_id

    ORDER BY [Total Writes] DESC, [Total Reads] DESC OPTION (RECOMPILE);

    use either DBCC show_statistics to get date stats last updated, or the stats_date function, something like this

    select 'index name' = i.name,

    'stats date' = stats_date(i.object_id,i.index_id)

    from sys.objects o, sys.indexes i

    where o.name = 'tablename' and o.object_id = i.object_id

    ---------------------------------------------------------------------