The last post showed how to get the rows for all tables in a given database without doing a table scan. No table scan means the row count can be retrieved very quickly, even with millions of rows in the table.
This post improves on that by making it partition-aware. That is, if a table happens to be partitioned, this code breaks down the rows per partition. That is something that is very useful when managing large tables and storage requirements.
Another improvement demonstrated is instead of showing this information for all tables in one database, it will be shown how to create a “dynamic view” which will show the tables for all databases in this instance of SQL Server. This is done be making a view that UNIONs the query for each database.
But, such a view creates a maintenance problem. When a database is added or removed from the server, the view will be inaccurate (database has been added) or will result in an error (database has been removed). Re-creating the view manually when a database is added or removed would be tedious.
The strategy presented here will be to write a proc that cycles through a list of databases on the instance, and then creates the view. The view should then be accurate until a database is removed from the instance (in which case querying the view would generate an error), or a database is added to the instance (in which case the view would not include the new database).
Therefore, anytime a database is added or removed, you would run the proc which generates the view to keep it up-to-date.
I strongly suggest that you create a special database to contain this and all subsequent administrative code. Some DBAs prefer to put these code snippets into master or msdb, and there are good reasons to support that, but my preference is to put it into a separate user database. I call mine Admin, but you can call it any other name that you prefer.
First, let’s create the proc which creates the view.
CREATE PROC dbo.CreateVwPartitionRaw
@ShowSql bit = 0
AS
/* DATE AUTHOR REMARKS
12/12/10 PPaiva Initial creation.
DESCRIPTION
Creates a view in the Admin database for all table/partition
info for all non-system databases on this server.
Name of view is vwPartitionRaw.
System tables are excluded.
Coded to use Convert(varchar, ServerProperty('ServerName'))
rather than @@ServerName since the latter can be erroneous.
USAGE
Exec Admin..CreateVwPartitionRaw 1
SELECT *
FROM Admin..vwPartitionRaw
*/
SET NOCOUNT ON
DECLARE @s varchar(max),
@DB varchar(100),
@MaxDB varchar(100),
@i int,
@sNow varchar(16)
SET @sNow = Convert(varchar(16), GetDate(), 120)
SET @s = 'IF Object_ID(''dbo.vwPartitionRaw'') Is Not Null
DROP VIEW dbo.vwPartitionRaw
'
IF @ShowSql = 1
Print @s
Exec(@s)
Print ''
SET @s = 'CREATE VIEW dbo.vwPartitionRaw
AS
/* DATE AUTHOR REMARKS
' + Convert(varchar(10), GetDate(), 01) + ' PPaiva Intial creation.
DESCRIPTION
Provides a list of non-system tables and partitions
for all non-system databases on this server.
This view provides the number of rows per partition,
among other partition attributes.
This view should be scheduled to auto-refresh daily.
To manually refresh this view:
Exec Admin.dbo.CreateVwPartitionRaw
SELECT *
FROM Admin..vwPartitionRaw
ORDER BY Server, DB, SchemaName, TableName, PartNum
*/
'
SELECT *
INTO #DBs
FROM sys.databases
WHERE state_desc = 'ONLINE'
SELECT @MaxDB = Max(Name),
@DB = '',
@i = 0
FROM #DBs
WHILE @DB < @MaxDB
BEGIN
SET @i = @i + 1
SELECT @DB = Min(Name)
FROM #DBs
WHERE Name > @DB
SET @s = @s + '
SELECT '
SET @s = @s + 'Convert(varchar, ServerProperty(''ServerName'')) as Server,
''' + @DB + ''' as DB,
sc.name COLLATE SQL_Latin1_General_CP1_CI_AS SchemaName,
t.name COLLATE SQL_Latin1_General_CP1_CI_AS TableName,
p.partition_number PartNum,
p.Rows,
p.object_id,
p.index_id,
p.partition_id PartID,
au.total_pages,
au.used_pages,
au.data_pages,
au.container_id,
''' + @sNow + ''' ViewCreateDate
FROM [' + @DB + '].sys.partitions p
LEFT JOIN [' + @DB + '].sys.allocation_units au
ON p.hobt_id = au.container_id
JOIN [' + @DB + '].sys.tables t
ON t.object_id = p.object_id
JOIN [' + @DB + '].sys.schemas sc
ON sc.schema_id = t.schema_id
WHERE p.index_id In (0, 1) -- 0 = heap, 1 = has clustered index
AND au.type = 1 -- in-row-data only, not LOB, not row-overflow-data, not dropped
AND sc.name <> ''sys''
'
IF @DB <> @MaxDB
'
END
IF @ShowSql = 1
BEGIN
SELECT *
FROM #DBs
ORDER BY Name
Print @s
END
Exec (@s)
Now, run the proc. Notice you can optionally pass in a “1” to show the SQL within the view that is about to be created. This is useful for debugging or just being curious.
Exec Admin.dbo.CreateVwPartitionRaw 1
Finally, we are now ready to use the new view.
-- Sort by the largest tables on this instance
SELECT *
FROM Admin.dbo.vwPartitionRaw
ORDER BY Rows desc
Note there is a column called PartNum. If you have any partitioned tables, the row count will be broken-down by partitions.
Or if you are after a simple view to retrieve row counts (not partition-aware) then you can make a view like this:
CREATE VIEW dbo.vwTable
AS
/* DATE AUTHOR REMARKS
12/12/10 PPaiva Initial creation.
-- Alphabetical list of all tables
SELECT *
FROM vwTable
ORDER BY Server, DB, SchemaName, TableName
-- Largest tables
SELECT *
FROM vwTable
ORDER BY Rows desc
*/
SELECT Server, DB, SchemaName, TableName, SUM(Rows) Rows
FROM vwPartitionRaw
GROUP BY Server, DB, SchemaName, TableName
Use Admin
go