July 4, 2013 at 4:33 pm
Is there a way to calculate the size (in MB) of auto-created statistics objects in a database?
I would like to get an idea of the space savings I would get from dropping duplicate statistics;
ie. single-column auto-created stats named "_WA_Sys_..." defined on the same column as the leading key of a non-clustered index.
What is the physical footprint of these objects in a db?
Here is my first attempt, but this does not give me the size of these stats objects:
SELECT
s.name
,ps.used_page_count * 8192 / (1024 * 1024) AS Size_MB
FROM
sys.dm_db_partition_stats ps
INNER JOIN
sys.stats s
ON
ps.[object_id] = s.[object_id]
WHERE
s.auto_created = 1
ORDER BY
ps.used_page_count DESC;
__________________________________________________________________________________
SQL Server 2016 Columnstore Index Enhancements - System Views for Disk-Based Tables[/url]
Persisting SQL Server Index-Usage Statistics with MERGE[/url]
Turbocharge Your Database Maintenance With Service Broker: Part 2[/url]
July 5, 2013 at 6:53 am
Hi,
Stats are stored in a binary large object called a statsblob. These are very small, even with very large tables, and you will not find any performance gains by cleaning them up.
You can see the blob by using a DAC to run the following code.
SELECT
OBJECT_NAME(s.object_id),
s.name,
DATALENGTH(o.imageval) / 1024. AS StatsSize_Kb
FROM
sys.stats AS s
INNER JOIN
sys.sysobjvalues AS o
ON s.object_id = o.objid
AND s.stats_id = o.subobjid
WHERE
OBJECTPROPERTY(s.object_id, 'IsSystemTable') = 0
ORDER BY
3 DESC;
July 5, 2013 at 8:53 am
Sean Pearce (7/5/2013)
Hi,Stats are stored in a binary large object called a statsblob. These are very small, even with very large tables, and you will not find any performance gains by cleaning them up.
You can see the blob by using a DAC to run the following code.
SELECT
OBJECT_NAME(s.object_id),
s.name,
DATALENGTH(o.imageval) / 1024. AS StatsSize_Kb
FROM
sys.stats AS s
INNER JOIN
sys.sysobjvalues AS o
ON s.object_id = o.objid
AND s.stats_id = o.subobjid
WHERE
OBJECTPROPERTY(s.object_id, 'IsSystemTable') = 0
ORDER BY
3 DESC;
Great! Thank you, I will add this script to my library.
I actually did a check; measured free space in my db files before and after dropping duplicate statistics and found the space savings to be indeed very small, of the order of 1 MB on my 100-GB database.
Having said that, don't the duplicate stats add overhead to update-stats operations? For example, if a large table has duplicate stats and one performs an "UPDATE STATISTICS .. WITH FULLSCAN" on it, then the performance of this operation would be expected to improve after dropping the duplicate stats.
Any thoughts on that?
Thanks again for the input!
__________________________________________________________________________________
SQL Server 2016 Columnstore Index Enhancements - System Views for Disk-Based Tables[/url]
Persisting SQL Server Index-Usage Statistics with MERGE[/url]
Turbocharge Your Database Maintenance With Service Broker: Part 2[/url]
July 5, 2013 at 8:58 am
I'm getting this error when running the above script (on both SQL 2008 and SQL 2012):
Msg 208, Level 16, State 1, Line 2
Invalid object name 'sys.sysobjvalues'.
__________________________________________________________________________________
SQL Server 2016 Columnstore Index Enhancements - System Views for Disk-Based Tables[/url]
Persisting SQL Server Index-Usage Statistics with MERGE[/url]
Turbocharge Your Database Maintenance With Service Broker: Part 2[/url]
July 5, 2013 at 9:15 am
you missed Sean's snippet where you have to use a DAC(Dedicated Admin Connection) in order to see the statsblob; if you do that, the dmv sys.sysobvalues would be accessible.
Lowell
July 5, 2013 at 10:40 am
Lowell (7/5/2013)
you missed Sean's snippet where you have to use a DAC(Dedicated Admin Connection) in order to see the statsblob; if you do that, the dmv sys.sysobvalues would be accessible.
Ah yes, my bad; I'll try that.
Incidentally I did a little test updating the stats of a 1-GB table before and after deleting duplicate stats.
I found a 20% reduction in execution time of the UPDATE-STATS command after dropping the duplicate stats.
__________________________________________________________________________________
SQL Server 2016 Columnstore Index Enhancements - System Views for Disk-Based Tables[/url]
Persisting SQL Server Index-Usage Statistics with MERGE[/url]
Turbocharge Your Database Maintenance With Service Broker: Part 2[/url]
Viewing 6 posts - 1 through 5 (of 5 total)
You must be logged in to reply to this topic. Login to reply