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


Statistics on tables


Statistics on tables

Author
Message
Rem70Rem
Rem70Rem
SSChasing Mays
SSChasing Mays (611 reputation)SSChasing Mays (611 reputation)SSChasing Mays (611 reputation)SSChasing Mays (611 reputation)SSChasing Mays (611 reputation)SSChasing Mays (611 reputation)SSChasing Mays (611 reputation)SSChasing Mays (611 reputation)

Group: General Forum Members
Points: 611 Visits: 745
Hi,

Is there a way to generate a script or extract all existing statistics in a databases? I would like to replicate the statistics on a different server.

Thanks
Adi Cohn
Adi Cohn
SSCarpal Tunnel
SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)

Group: General Forum Members
Points: 4469 Visits: 6515
You can see the statistics by running dbcc show_statistics (you can read about it BOL which is the help that is installed when you install SQL Server’s client tools). As much as I know you can only see the statistics or use UPDATE STATISTICS statement (again, you can see details about it in BOL) to update the statistics on a table or view, but you can not insert your own statistics that were taken from a different server.

Adi

--------------------------------------------------------------
To know how to ask questions and increase the chances of getting asnwers:
http://www.sqlservercentral.com/articles/Best+Practices/61537/

For better answers on performance questions, click on the following...
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/
Rem70Rem
Rem70Rem
SSChasing Mays
SSChasing Mays (611 reputation)SSChasing Mays (611 reputation)SSChasing Mays (611 reputation)SSChasing Mays (611 reputation)SSChasing Mays (611 reputation)SSChasing Mays (611 reputation)SSChasing Mays (611 reputation)SSChasing Mays (611 reputation)

Group: General Forum Members
Points: 611 Visits: 745
Thanks Adi for your reply.

I don't want to transfer the statistics number but just the definition on the ones created with the "create statistics" command. Some statistics were create and I would like to replicate the definition on another database.

Thanks
Dmitriy Burtsev
Dmitriy Burtsev
SSC Veteran
SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)SSC Veteran (243 reputation)

Group: General Forum Members
Points: 243 Visits: 445
create view dbo.v_stat as
select c.name as ColumnName, sc.stats_column_id, s.name as StatName, OBJECT_NAME(sc.object_id) as TblName
from sys.stats_columns sc
inner join sys.columns c on sc.column_id = c.column_id and sc.object_id = c.object_id
inner join sys.stats s on s.stats_id = sc.stats_id and sc.object_id = s.object_id
left outer join sys.indexes i on i.index_id = s.stats_id and i.object_id = s.object_id
where i.name is null
go
select distinct 'CREATE STATISTICS [' + v.StatName + '] on dbo.' + v.TblName + '(' + a.Fields + ');'
from dbo.v_stat v
join (select Fields = replace ((select ColumnName as 'data()'
from dbo.v_stat where StatName = s.StatName
for xml path('')), ' ',','),
s.StatName
from dbo.v_stat s
group by s.StatName ) as a on a.StatName = v.StatName;
M&M
M&M
SSCarpal Tunnel
SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)

Group: General Forum Members
Points: 4141 Visits: 3909
Rem-487422 (7/20/2009)
Hi,

Is there a way to generate a script or extract all existing statistics in a databases? I would like to replicate the statistics on a different server.

Thanks


Rem,

I guess I understood your question. You want to create a statistics only database right?
That means, you don't want to worry about the underlying data but just the statistics so that you
could simulate a similar database environment.

Well, if you are looking for this, this is possible and some people refer to it as database cloning.
For more details, you could refer this link below, which is very useful.

http://support.microsoft.com/default.aspx?scid=kb;EN-US;914288

With this, we could clone a database without having to worry about the data. We would be able to simulate the same conditions as in the original database. The prerequisite is you need to have atleast SQL Server 2005 SP2 and above.

M&M
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