Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 12»»

Best Index Rebuild/Reorganize and Update Statistics Strategy Expand / Collapse
Author
Message
Posted Sunday, July 14, 2013 12:02 PM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Sunday, August 17, 2014 3:50 AM
Points: 329, Visits: 858

I have a several databases in full recovery model around 200 GB. As soon I run maintenace plan, log fills out pretty quickly. Is it better to change recover model to simple while perfroming maintenance? And then change back to full after complete? Will this way not fill the log too quickly?

Also, doesn't see like we need to upate all the statistics or rebuild all indexes as maintaining all of them seems resource consuming. Is there a dmv that we can use to show which indexes/statistics are mostly used and just trying to do maintenace on those?

I am just worried the log getting full and we will have another problem.

I am on 2005.

This is kind of urgent as some of the query recently starting running longer as we had outdated statistics.

Please advise.
Post #1473372
Posted Sunday, July 14, 2013 12:46 PM
SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 11:08 AM
Points: 5,992, Visits: 12,941
bulk logged is the best mode to control growth during index rebuilds, then a full backup afterwards. Note log backups will still be large though. You could also try backing up the log more frequently during reindexing.

You are correct to try and only rebuild indexes that need it, the dmv for that is sys.dm_db_index_physical_stats. This will also reduce log activity. There are many scripts for that, I enclose the one from BOL which works just fine plus the crowd favorite is Olla Hallengrens suite of utilities for maintenance.

For those indexes which are only reorganised you will still need to update the stats.


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



  Post Attachments 
reindex_basedon_fragmentation.txt (51 views, 2.62 KB)
Post #1473377
Posted Wednesday, July 17, 2013 9:03 PM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Sunday, August 17, 2014 3:50 AM
Points: 329, Visits: 858
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?
Post #1474867
Posted Thursday, July 18, 2013 6:56 AM
SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 11:08 AM
Points: 5,992, Visits: 12,941
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


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

Post #1475015
Posted Thursday, July 18, 2013 6:57 AM
SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 11:08 AM
Points: 5,992, Visits: 12,941
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


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

Post #1475018
Posted Friday, July 19, 2013 1:31 PM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Sunday, August 17, 2014 3:50 AM
Points: 329, Visits: 858
Thank you. Thanks for the query to find out heavily used indexes. Using this, as far as statistics are concerened, we won't be able to capture _WA statistics but only the indexed based statistics. So, should we update all the statistics on the table? This would be very time consuming. Any idea how to pull the heavily used WA statistics?
Post #1475661
Posted Friday, July 19, 2013 2:29 PM
SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 11:08 AM
Points: 5,992, Visits: 12,941
SQL_Surfer (7/19/2013)
Thank you. Thanks for the query to find out heavily used indexes. Using this, as far as statistics are concerned, we won't be able to capture _WA statistics but only the indexed based statistics. So, should we update all the statistics on the table? This would be very time consuming. Any idea how to pull the heavily used WA statistics?


I don't know of a query to do that.

Have you tried updating all stats? updating the stats would only be time consuming if you run them all with full scan. run an sp_updatestats periodically if you have doubts about the age of your stats. Index rebuilds will update the stats, and you can rebuild the stats for those indexes reorganised.


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

Post #1475685
Posted Saturday, July 20, 2013 11:20 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Sunday, August 17, 2014 3:50 AM
Points: 329, Visits: 858
I ran the following statments

SELECT ps.database_id, ps.OBJECT_ID,
ps.index_id, b.name,
ps.avg_fragmentation_in_percent
FROM sys.dm_db_index_physical_stats (DB_ID(), NULL, NULL, NULL, NULL) AS ps
INNER JOIN sys.indexes AS b ON ps.OBJECT_ID = b.OBJECT_ID
AND ps.index_id = b.index_id
WHERE ps.database_id = DB_ID()
ORDER BY ps.OBJECT_ID

I see some of the index_id = 0 and name is NULL but with highger fragmentation. Then I looked up the object with index_id = 0 and turned out its a table. What does a table with higher fragmentation means? one of them was about 98%. How can we reduce the fragmentaion on the table?
Post #1475761
Posted Saturday, July 20, 2013 11:50 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Today @ 7:57 AM
Points: 43,045, Visits: 36,205
index_id of 0 and name of NULL means it's a heap, a table without a clustered index. You can't rebuild a heap.

And in case anyone posts the 'create a clustered index and then drop it' bad advice...
http://www.sqlskills.com/blogs/paul/a-sql-server-dba-myth-a-day-2930-fixing-heap-fragmentation/



Gail Shaw
Microsoft Certified Master: SQL Server 2008, MVP
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass

Post #1475763
Posted Sunday, July 21, 2013 9:02 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Sunday, August 17, 2014 3:50 AM
Points: 329, Visits: 858
Any idea why DB grows to 10GB more after index maintenance? Should I opt for shrinkfile?
Post #1475822
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse