x

counting the number of rows in a table

What is the fastest way of counting the number of rows in a table? All tables have PrimaryKeys on them.

more ▼

asked Oct 21, 2009 at 03:37 PM in Default

avatar image

Raj More
1.8k 82 87 90

(comments are locked)
10|1200 characters needed characters left

5 answers: sort voted first

If you can deal with a rough count on SQL 2000 - you can query sysindexes - something like

SELECT rowcnt FROM sysindexes WHERE id = OBJECT_ID('MyTableName') and indid in (0, 1)

Under SQL 2005+ the equivalent would be

SELECT [record_count] FROM [sys].[dm_db_index_physical_stats](DB_ID(), OBJECT_ID('MyTableName'), NULL, NULL, 'SAMPLED')
WHERE [index_id] IN (0, 1)

The row count returned from 2005+ will be accurate, unless your table has no clustered index (i.e. is a heap).

These methods are orders of magnitude faster than counting all the rows using COUNT().

more ▼

answered Oct 21, 2009 at 04:01 PM

avatar image

Matt Whitfield ♦♦
29.5k 62 66 88

(comments are locked)
10|1200 characters needed characters left

You could also use:

SELECT row_count 
FROM sys.dm_db_partition_stats
WHERE OBJECT_ID = OBJECT_ID('TableName')
        AND index_id =1

I specified index_id = 1, since you mentioned that all table have a PK, which I inferred to be the clustered index. You could also specify index_id < 2, which would account for a HEAP table

more ▼

answered Oct 21, 2009 at 04:20 PM

avatar image

Jay Bonk
1.4k 2 4

You should use SUM(row_count) to return total rows in the table in case the table has more partitions.

Jul 21, 2010 at 08:22 AM Pavel Pawlowski
(comments are locked)
10|1200 characters needed characters left

EXEC sp_spaceused 'MyTableName'

one of the returned columns is "rows"

Alternatively, of course, you can run:

SELECT COUNT(*) FROM MyTableName

If you need to store the count in a variable, then use this:

SET @MyVar = (SELECT COUNT(*) FROM MyTableName)
more ▼

answered Oct 21, 2009 at 03:52 PM

avatar image

Tom Staab ♦
14.5k 7 14 18

(comments are locked)
10|1200 characters needed characters left

I use the dm_db_index_physical_stats as well. it runs nightly as part of maintenance

more ▼

answered Oct 21, 2009 at 04:19 PM

avatar image

alen teplitsky
21 2 2 4

(comments are locked)
10|1200 characters needed characters left
Your answer
toggle preview:

Up to 2 attachments (including images) can be used with a maximum of 524.3 kB each and 1.0 MB total.

Follow this question

By Email:

Once you sign in you will be able to subscribe for any updates here

By RSS:

Answers

Answers and Comments

SQL Server Central

Need long-form SQL discussion? SQLserverCentral.com is the place.

Topics:

x2018
x1066

asked: Oct 21, 2009 at 03:37 PM

Seen: 3270 times

Last Updated: Oct 21, 2009 at 04:12 PM

Copyright 2016 Redgate Software. Privacy Policy