Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Size of auto-created statistics objects in a database


Size of auto-created statistics objects in a database

Author
Message
Marios Philippopoulos
Marios Philippopoulos
SSCommitted
SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)

Group: General Forum Members
Points: 1954 Visits: 3740
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
Persisting SQL Server Index-Usage Statistics with MERGE
Turbocharge Your Database Maintenance With Service Broker: Part 2
Sean Pearce
Sean Pearce
Ten Centuries
Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)

Group: General Forum Members
Points: 1170 Visits: 3432
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;





The SQL Guy @ blogspot

@SeanPearceSQL

About Me
Marios Philippopoulos
Marios Philippopoulos
SSCommitted
SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)

Group: General Forum Members
Points: 1954 Visits: 3740
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
Persisting SQL Server Index-Usage Statistics with MERGE
Turbocharge Your Database Maintenance With Service Broker: Part 2
Marios Philippopoulos
Marios Philippopoulos
SSCommitted
SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)

Group: General Forum Members
Points: 1954 Visits: 3740
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
Persisting SQL Server Index-Usage Statistics with MERGE
Turbocharge Your Database Maintenance With Service Broker: Part 2
Lowell
Lowell
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14929 Visits: 38913
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

--
help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

Marios Philippopoulos
Marios Philippopoulos
SSCommitted
SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)

Group: General Forum Members
Points: 1954 Visits: 3740
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
Persisting SQL Server Index-Usage Statistics with MERGE
Turbocharge Your Database Maintenance With Service Broker: Part 2
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