SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Statistics Outdated


Statistics Outdated

Author
Message
Site Owners
Site Owners
SSC Guru
SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)

Group: Administrators
Points: 62519 Visits: 402
Comments posted to this topic are about the item Statistics Outdated
MadAdmin
MadAdmin
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10044 Visits: 2060
Just wondering what these stats would be used for.
Cos if stats are outdated then that implies they are not being used, since queries would start the process of autorecomputing stats, if it is enabled, and the stats are used in that query.
So this could be a good script in finding stats that need to be dropped.

Catch-all queries done right
Gail Shaw's Performance Blog
Chris Harshman
Chris Harshman
SSC-Dedicated
SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)

Group: General Forum Members
Points: 36909 Visits: 7037
If statistics are out of date, that does NOT mean that they aren't being used, that typically means that the table they are on is large enough that SQL Server's built in rule about only autoupdating statistics after 20% modifications doesn't kick in frequently enough. If a table has 10,000,000 rows in it, autoupdate of statistics won't happen until after 2,000,000 rows have been inserted/updated.
https://www.sqlskills.com/blogs/erin/understanding-when-statistics-will-automatically-update/

There were some changes to this behavior introduced in SQL Server 2016:
https://www.brentozar.com/archive/2016/03/changes-to-auto-update-stats-thresholds-in-sql-server-2016/
Andy Robertson
Andy Robertson
Hall of Fame
Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)

Group: General Forum Members
Points: 3300 Visits: 607

I think this is only applicable to SQL Server 2008 R2 and above.
sys.dm_db_stats_properties
is not on my SQL Server 2008 instances


Chris Harshman
Chris Harshman
SSC-Dedicated
SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)

Group: General Forum Members
Points: 36909 Visits: 7037
for older versions, you'd probably have to look at sys.sysindexes and the STATS_DATE function to see out of date stats, maybe something like this:
SELECT OBJECT_SCHEMA_NAME(i.OBJECT_ID) AS TableSchema, OBJECT_NAME(i.OBJECT_ID) AS TableName, o.type_desc AS ObjectType, i.[name] AS StatisticsName, STATS_DATE(i.OBJECT_ID, i.index_id) AS StatisticsUpdateDate, si.rowmodctr AS RecordsModified, si.rowcnt AS TotalRecords, i.has_filter
FROM sys.indexes i
INNER JOIN sys.objects o ON i.OBJECT_ID=o.OBJECT_ID
INNER JOIN sys.sysindexes si ON i.OBJECT_ID=si.id AND i.index_id=si.indid
WHERE o.TYPE <> 'S'
AND STATS_DATE(i.OBJECT_ID, i.index_id) IS NOT NULL
AND si.rowmodctr > 0
UNION ALL
SELECT OBJECT_SCHEMA_NAME(o.OBJECT_ID) AS TableSchema, OBJECT_NAME(o.OBJECT_ID) AS TableName, o.type_desc AS ObjectType, s.name AS StatisticsName, STATS_DATE(o.OBJECT_ID, s.stats_id) AS statisticsUpdateDate, si.rowmodctr AS RecordsModified, ir.rowcnt AS TotalRecords, s.has_filter
FROM sys.stats s
INNER JOIN sys.objects o ON s.OBJECT_ID=o.OBJECT_ID
INNER JOIN sys.sysindexes si ON s.OBJECT_ID=si.id AND s.stats_id= si.indid
INNER JOIN (SELECT id,rowcnt FROM sys.sysindexes WHERE indid IN (0,1)) IR ON IR.id=o.OBJECT_ID
WHERE o.TYPE <> 'S'
AND (s.auto_created=1 OR s.user_created=1)AND STATS_DATE(o.OBJECT_ID, s.stats_id) IS NOT NULL
AND si.rowmodctr > 0
ORDER BY RecordsModified DESC

Andy Robertson
Andy Robertson
Hall of Fame
Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)

Group: General Forum Members
Points: 3300 Visits: 607
Chris Harshman - Friday, June 8, 2018 10:15 AM
for older versions, you'd probably have to look at sys.sysindexes and the STATS_DATE function to see out of date stats, maybe something like this:
SELECT OBJECT_SCHEMA_NAME(i.OBJECT_ID) AS TableSchema, OBJECT_NAME(i.OBJECT_ID) AS TableName, o.type_desc AS ObjectType, i.[name] AS StatisticsName, STATS_DATE(i.OBJECT_ID, i.index_id) AS StatisticsUpdateDate, si.rowmodctr AS RecordsModified, si.rowcnt AS TotalRecords, i.has_filter
FROM sys.indexes i
INNER JOIN sys.objects o ON i.OBJECT_ID=o.OBJECT_ID
INNER JOIN sys.sysindexes si ON i.OBJECT_ID=si.id AND i.index_id=si.indid
WHERE o.TYPE <> 'S'
AND STATS_DATE(i.OBJECT_ID, i.index_id) IS NOT NULL
AND si.rowmodctr > 0
UNION ALL
SELECT OBJECT_SCHEMA_NAME(o.OBJECT_ID) AS TableSchema, OBJECT_NAME(o.OBJECT_ID) AS TableName, o.type_desc AS ObjectType, s.name AS StatisticsName, STATS_DATE(o.OBJECT_ID, s.stats_id) AS statisticsUpdateDate, si.rowmodctr AS RecordsModified, ir.rowcnt AS TotalRecords, s.has_filter
FROM sys.stats s
INNER JOIN sys.objects o ON s.OBJECT_ID=o.OBJECT_ID
INNER JOIN sys.sysindexes si ON s.OBJECT_ID=si.id AND s.stats_id= si.indid
INNER JOIN (SELECT id,rowcnt FROM sys.sysindexes WHERE indid IN (0,1)) IR ON IR.id=o.OBJECT_ID
WHERE o.TYPE <> 'S'
AND (s.auto_created=1 OR s.user_created=1)AND STATS_DATE(o.OBJECT_ID, s.stats_id) IS NOT NULL
AND si.rowmodctr > 0
ORDER BY RecordsModified DESC

Thanks very much for the update. This works fine on my 2008 instance.

Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum








































































































































































SQLServerCentral


Search