Skip to content

Instantly share code, notes, and snippets.

@jonashaag
Last active January 8, 2024 16:35
Show Gist options
  • Save jonashaag/80fc162784118f8b4929149228f1f242 to your computer and use it in GitHub Desktop.
Save jonashaag/80fc162784118f8b4929149228f1f242 to your computer and use it in GitHub Desktop.
SQL Server quickly count number of rows in table
-- Count number of rows in a table quickly (without a full table/index scan).
-- Usage:
-- sp_count 'mydb.dbo.mytable' Get the row count of the given table.
-- sp_count 'dbo.mytable' Get the row count of the given table from the current database.
-- sp_count Get a list of tables and row counts in the current database.
USE [master]
GO
DROP PROCEDURE IF EXISTS [dbo].[sp_count]
GO
CREATE PROCEDURE [dbo].[sp_count]
@table VARCHAR(MAX) = NULL
AS
BEGIN
IF @table IS NULL
BEGIN
SELECT OBJECT_NAME(s.object_id) AS table_name
, SUM(row_count) AS row_count
FROM sys.dm_db_partition_stats s
JOIN sys.objects o
ON s.object_id = o.object_id
WHERE s.index_id IN (0, 1)
AND o.type_desc = 'USER_TABLE'
GROUP BY OBJECT_NAME(s.object_id)
ORDER BY OBJECT_NAME(s.object_id)
END
ELSE
BEGIN
DECLARE @database VARCHAR(MAX) = PARSENAME(@table, 3)
IF (@database IS NULL)
BEGIN
SET @database = DB_NAME()
SET @table = @database + '.' + @table
END
DECLARE @row_count_query NVARCHAR(MAX) = (
'USE ' + QUOTENAME(@database) + ';' +
'SELECT @count = SUM(s.row_count)
FROM sys.dm_db_partition_stats s
WHERE s.index_id IN (0, 1)
AND s.object_id = OBJECT_ID(''' + @table + ''')'
)
DECLARE @count BIGINT
EXEC sp_executesql @row_count_query, N'@count VARCHAR(MAX) OUTPUT', @count = @count OUTPUT
IF (@count IS NULL)
BEGIN
DECLARE @msg VARCHAR(MAX) = (SELECT 'Table "' + @table + '" not found')
RAISERROR(@msg, 16, 1)
END
ELSE
BEGIN
SELECT @count AS row_count
END
END
END
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment