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


Find all published tables with row counts and table size


Find all published tables with row counts and table size

Author
Message
Jim Youmans-439383
Jim Youmans-439383
SSC Veteran
SSC Veteran (217 reputation)SSC Veteran (217 reputation)SSC Veteran (217 reputation)SSC Veteran (217 reputation)SSC Veteran (217 reputation)SSC Veteran (217 reputation)SSC Veteran (217 reputation)SSC Veteran (217 reputation)

Group: General Forum Members
Points: 217 Visits: 522
Comments posted to this topic are about the item Find all published tables with row counts and table size
tina.huaarroyo
tina.huaarroyo
Grasshopper
Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)

Group: General Forum Members
Points: 18 Visits: 3
I ran the script on SQL Sever2014 and got an error at lines
SET @command = '
.
.
.
END';
jeffgonnering
jeffgonnering
Old Hand
Old Hand (321 reputation)Old Hand (321 reputation)Old Hand (321 reputation)Old Hand (321 reputation)Old Hand (321 reputation)Old Hand (321 reputation)Old Hand (321 reputation)Old Hand (321 reputation)

Group: General Forum Members
Points: 321 Visits: 525
Thanks, but this script only works if you have a local distribution database (and that it is named [distribution]). The publication/article data is available in each publisher DB in [dbo].[syspublications] and [dbo].[sysarticles] tables that you could include in your MSforeachdb command.


-- create table with only the names of databases that are published
SELECT name as [DatabaseName]
INTO #tmpPubDatabases
FROM sys.databases
WHERE database_id > 4
AND is_published = 1;


-- create table to hold the table info (name, schema,row count, space used)
CREATE TABLE #tmpTableSizes(
DBName VARCHAR(256),
PublicationName VARCHAR(256),
ArticleName VARCHAR(256),
SchemaName VARCHAR(256),
TableName VARCHAR(256),
RowCounts INT,
TotalSpaceMB DECIMAL(18,2)
);


DECLARE @command VARCHAR(MAX);


-- run this in all the databases that have publications
SET @command = '
USE [?]

IF DB_NAME() IN (SELECT DatabaseName FROM #tmpPubDatabases)

INSERT #tmpTableSizes
SELECT
DB_NAME() AS [DBName],
[sp].[name] AS [PublicationName],
[sa].[name] AS [ArticleName],
[s].[name] AS [SchemaName],
[t].[name] AS [TableName],
[p].[rows] AS [RowCounts],
(SUM([a].[total_pages]) * 8) / 1024.0 AS [TotalSpaceMB]
FROM
[dbo].[syspublications] [sp]
INNER JOIN [dbo].[sysarticles] [sa]
ON [sa].[pubid] = [sp].[pubid]
INNER JOIN [sys].[tables] [t]
ON [t].[object_id] = [sa].[objid]
INNER JOIN [sys].[indexes] [i]
ON [t].[object_id] = [i].[object_id]
INNER JOIN [sys].[partitions] [p]
ON [i].[object_id] = [p].[object_id]
AND [i].[index_id] = [p].[index_id]
INNER JOIN [sys].[allocation_units] [a]
ON [p].[partition_id] = [a].[container_id]
LEFT OUTER JOIN [sys].[schemas] [s]
ON [t].[schema_id] = [s].[schema_id]
WHERE
[t].[name] NOT LIKE ''dt%''
AND [t].[is_ms_shipped] = 0
AND [i].[object_id] > 255
GROUP BY
[sp].[name],
[sa].[name],
[s].[name],
[t].[name],
[p].[rows]
';

-- run for all affected databases
EXEC sp_MSforeachdb @command

SELECT
*
FROM
[#tmpTableSizes] AS [tts]
ORDER BY
[tts].[DBName],
[tts].[PublicationName],
[tts].[TableName];


-- clean up
DROP TABLE #tmpTableSizes;
DROP TABLE #tmpPubDatabases;




tina.huaarroyo
tina.huaarroyo
Grasshopper
Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)Grasshopper (18 reputation)

Group: General Forum Members
Points: 18 Visits: 3
Thanks for the tip on the database name. What I don't understand is on the line Set @command = '. This line has a single quote after the @command and the other quote is way after the END line.
Do you mean the whole block from Use [database name] to End is meant to be included in the single quotes?
Jim Youmans-439383
Jim Youmans-439383
SSC Veteran
SSC Veteran (217 reputation)SSC Veteran (217 reputation)SSC Veteran (217 reputation)SSC Veteran (217 reputation)SSC Veteran (217 reputation)SSC Veteran (217 reputation)SSC Veteran (217 reputation)SSC Veteran (217 reputation)

Group: General Forum Members
Points: 217 Visits: 522
This script is meant to be run on the distributor in the distributor database as mentioned above.

I am using the sp_MSforeachDB stored procedure which takes a query as a parameter and runs it against each DB on the server. The SQL that is being run against each database is in the @command variable. That is the reason for the SQL in single quotes.

The ? will be replace by the database name as the sp_MSforeachDB cycles through each database on the server. Then the rest of the SQL will be ran in that database.

Sorry if that was not clear.
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