Blog Post

Fastest Way to Find Row Count of All Tables From All Databases in SQL Server

,

There are many times you as DBA or Developer needs to get all row count from all tables or row count of all tables from all Databases in a SQL Server. You may need a quick way to count the number of rows contained within the tables. The following SQL code will get you the row counts;

Get all row count from all tables in a Database

The below script helps you to find all the tables row count in a database.

SELECT 
@@servername as servername,
db_name() as databasename,    
    s.name AS schemaname,
t.name AS tablename,
    p.rows AS rowcounts,
    SUM(a.total_pages) * 8 AS totalspaceKB, 
    SUM(a.used_pages) * 8 AS usedspaceKB, 
    (SUM(a.total_pages) - SUM(a.used_pages)) * 8 AS unusedspaceKB,
getdate() as captureddatetime
FROM sys.tables t
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 
--and t.name =''XXXX'' ---- replace the XXXX with table name
GROUP BY 
t.name, s.name, p.Rows

Get all row counts of all tables from all Databases

The following script helps you to find all the tables row count from all the databases.

-- create table with only the names of databases that are published
SELECT 
name as databasename
INTO #alldatabases
FROM sys.databases WHERE database_id > 4
CREATE TABLE #alltablesizes(
servername sysname,
databasename sysname,
schemaName sysname,
tablename sysname,
rowcounts INT,
totalspaceKB DECIMAL(18,2),
usedspaceKB DECIMAL(18,2),
unusedspaceKB DECIMAL(18,2),
captureddatetime datetime
  );
DECLARE @command VARCHAR(MAX);
-- run the below code to get table count from all the databases 
SET @command = '
USE [?]
IF DB_NAME() IN (SELECT databasename FROM #alldatabases)
BEGIN
INSERT #alltablesizes
SELECT 
@@servername as servername,
db_name() as databasename,    
    s.name AS schemaname,
t.name AS tablename,
    p.rows AS rowcounts,
    SUM(a.total_pages) * 8 AS totalspaceKB, 
    SUM(a.used_pages) * 8 AS usedspaceKB, 
    (SUM(a.total_pages) - SUM(a.used_pages)) * 8 AS unusedspaceKB,
getdate() as captureddatetime
FROM sys.tables t
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 
--and t.name =''XXXX'' ---- replace the XXXX with table name
GROUP BY 
t.name, s.name, p.Rows
END';
EXEC sp_MSforeachdb @command
select * from #alltablesizes
order by 5 desc
drop table #alltablesizes
drop table #alldatabases

Hope, you enjoyed reading the article!

The post Fastest Way to Find Row Count of All Tables From All Databases in SQL Server appeared first on .

Rate

5 (1)

You rated this post out of 5. Change rating

Share

Share

Rate

5 (1)

You rated this post out of 5. Change rating