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

Size of auto-created statistics objects in a database Expand / Collapse
Author
Message
Posted Thursday, July 4, 2013 4:33 PM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Saturday, September 13, 2014 11:32 PM
Points: 1,862, Visits: 3,606
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;



__________________________________________________________________________________

Turbocharge Your Database Maintenance With Service Broker: Part 2
Turbocharge Your Database Maintenance With Service Broker: Part 1
Real-Time Tracking of Tempdb Utilization Through Reporting Services
Monitoring Database Blocking Through SCOM 2007 Custom Rules and Alerts
Preparing for the Unthinkable - a Disaster/Recovery Implementation
Post #1470528
Posted Friday, July 5, 2013 6:53 AM


SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Today @ 5:36 AM
Points: 906, Visits: 2,853
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
Post #1470714
Posted Friday, July 5, 2013 8:53 AM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Saturday, September 13, 2014 11:32 PM
Points: 1,862, Visits: 3,606
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!


__________________________________________________________________________________

Turbocharge Your Database Maintenance With Service Broker: Part 2
Turbocharge Your Database Maintenance With Service Broker: Part 1
Real-Time Tracking of Tempdb Utilization Through Reporting Services
Monitoring Database Blocking Through SCOM 2007 Custom Rules and Alerts
Preparing for the Unthinkable - a Disaster/Recovery Implementation
Post #1470777
Posted Friday, July 5, 2013 8:58 AM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Saturday, September 13, 2014 11:32 PM
Points: 1,862, Visits: 3,606
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'.


__________________________________________________________________________________

Turbocharge Your Database Maintenance With Service Broker: Part 2
Turbocharge Your Database Maintenance With Service Broker: Part 1
Real-Time Tracking of Tempdb Utilization Through Reporting Services
Monitoring Database Blocking Through SCOM 2007 Custom Rules and Alerts
Preparing for the Unthinkable - a Disaster/Recovery Implementation
Post #1470781
Posted Friday, July 5, 2013 9:15 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 9:23 AM
Points: 12,915, Visits: 32,074
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

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #1470788
Posted Friday, July 5, 2013 10:40 AM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Saturday, September 13, 2014 11:32 PM
Points: 1,862, Visits: 3,606
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.


__________________________________________________________________________________

Turbocharge Your Database Maintenance With Service Broker: Part 2
Turbocharge Your Database Maintenance With Service Broker: Part 1
Real-Time Tracking of Tempdb Utilization Through Reporting Services
Monitoring Database Blocking Through SCOM 2007 Custom Rules and Alerts
Preparing for the Unthinkable - a Disaster/Recovery Implementation
Post #1470814
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse