Database Journal
MS SQL Oracle DB2 Access MySQL PostgreSQL Sybase PHP SQL Etc SQL Scripts & Samples Links Database Forum

» Database Journal Home
» Database Articles
» Database Tutorials
MS SQL
Oracle
DB2
MS Access
MySQL
» RESOURCES
Database Tools
SQL Scripts & Samples
Links
» Database Forum
» Sitemap
Free Newsletters:
DatabaseDaily  
News Via RSS Feed


follow us on Twitter
Database Journal |DBA Support |SQLCourse |SQLCourse2
 

Featured Database Articles

MS SQL

Posted Jul 5, 2000

Alternative Way to Get the Table's Row Count

By Alexander Chigrik


To get the total row count in a table, we usually use the following select statement:

SELECT count(*) FROM 

This query will perform full table scan to get the row count. You can check it by setting SET SHOWPLAN ON for SQL Server 6.5 or SET SHOWPLAN_TEXT ON for SQL Server 7.0. So, if the table is very big, it can take a lot of time. This is the example of simple table creation and addition of new records into this table:

CREATE TABLE tbTest (
  id int identity primary key,
  Name char(10)
)
GO
DECLARE @i int
SELECT @i = 1
WHILE @i <= 10000
  BEGIN
    INSERT INTO tbTest VALUES (LTRIM(str(@i)))
    SELECT @i = @i + 1
  END
GO

There is another way to determine the total row count in a table. You can use sysindexes system table for this purpose. There is field ROWS in the sysindexes table. This field contains the total row count for each table in your database. So, you can use the following select statement instead above one:

SELECT rows FROM sysindexes
  WHERE id = OBJECT_ID('table_name') AND indid < 2

There are physical read and logical read operations. A logical read occurs if the page is currently in the cache. If the page is not currently in the cache, a physical read is performed to read the page into the cache. To see how many logical or physical read operations were made, you can use SET STATISTICS IO ON command.

This is the example:

SET STATISTICS IO ON
GO
SELECT count(*) FROM tbTest
GO
SELECT rows FROM sysindexes WHERE id = OBJECT_ID('tbTest') AND indid < 2
GO
SET STATISTICS IO OFF
GO

These are the results:

-----------
10000

(1 row(s) affected)

Table 'tbTest'. Scan count 1, logical reads 32, physical reads 0, read-ahead 
reads 0.
rows
-----------
10000

(1 row(s) affected)

Table 'sysindexes'. Scan count 1, logical reads 2, physical reads 0, 
read-ahead reads 0.

So, you can improve the speed of the first query in several times. This works for SQL Server 6.5 and SQL Server 7.0 as well.


» See All Articles by Columnist Alexander Chigrik




MS SQL Archives

Comment and Contribute

 


(Maximum characters: 1200). You have characters left.

 

 




Latest Forum Threads
MS SQL Forum
Topic By Replies Updated
SQL 2005: SSIS: Error using SQL Server credentials poverty 3 August 17th, 07:43 AM
Need help changing table contents nkawtg 1 August 17th, 03:02 AM
SQL Server Memory confifuration bhosalenarayan 2 August 14th, 05:33 AM
SQL Server Primary Key and a Unique Key katty.jonh 2 July 25th, 10:36 AM