Finding no. of Rows in all tables of a datbase in one line of script

  • Comments posted to this topic are about the item Finding no. of Rows in all tables of a datbase in one line of script

  • I wouldn't recommend running this on a very large database, you'd be waiting for some time and would cause a lot of contention, and to be honest I wouldn't use sp_MSforeachtable unless absolutely necessary...

  • i've done a T-SQL script to get the same result, but returns a layout that's easier to analyze the results

    set nocount on

    go

    create table #Tables_X_Record_Count

    (table_name varchar(max),

    record_count integer)

    go

    declare

    @cursor CURSOR,

    @table_name varchar(max),

    @record_count integer

    set @cursor = cursor for

    select name from

    (

    select * from sysobjects where xtype = 'U'

    ) user_tables order by name

    open @cursor

    fetch next from @cursor into @table_name

    while (@@fetch_status<>-1)

    begin

    INSERT INTO #Tables_X_Record_Count (table_name) VALUES (@table_name)

    exec (' update #Tables_X_Record_Count set record_count = (select COUNT(*) as contagem FROM '+@table_name+') where table_name = '''+@table_name+'''')

    fetch next from @cursor into @table_name

    end

    close @cursor

    deallocate @cursor

    select * from #Tables_X_Record_Count

    drop table #Tables_X_Record_Count

    set nocount off

  • I prefer using sp_spaceused to find table counts quickly. If you use OBJECT_DEFINITION() to find the body of sp_spaceused, you will see how they are determining the table count. Tying that up to all user tables, I get a fairly simple query below for my results:

    select object_name(p.object_id),

    SUM(case when (index_id < 2) then row_count else 0 end)

    from sys.dm_db_partition_stats p inner join sys.tables t on p.object_id = t.object_id

    where t.type = 'U'

    group by p.object_id

    order by object_name(p.object_id)

  • cvcscvcs: Use of CURSOR is avoidable here (and almost everywhere else) when you bang your head against the wall long enough.

    Same output format as yours:

    SELECT name, sum(row_count) AS MAX_MSG_ID

    FROM sys.dm_db_partition_stats WITH (NOLOCK), sysobjects WITH (NOLOCK)

    WHERE xtype = 'U'

    AND object_id = object_id('' + name + '')

    GROUP BY name

  • I agree with the last two postings, if you're confident your database stats are correct always try and use the Dynamic Management Views to looks at the table details if you're looking on SQL 2005 and above, and if you're using SQL 2000 I'd recommend using sp_spaceused as using 'SELECT COUNT(*)' can cause too many contention issues (and even when doing a count on one table try and do it for a single column, such as SELECT COUNT(ID))...

  • As "SELECT COUNT(*) FROM..." will be slow for large tables and may lock/block tables I suggest run the following command instead:

    sp_MSforeachtable @command1="print '?'", @command2="sp_spaceused '?'"

    To see the pretty big difference between the two please run each of the following statements against a 1million+ rows table (mine has over 100million rows and is no time for sp_spaceused VS 47 seconds for count):

    select count(*) from clients;

    exec sp_spaceused clients;

  • ron.mcdowell

    Right! Definitely is better not to use the cursor, it works good for me

    because my database was very small, but I'll never use it in this kind of

    situation anymore, with the sys.dm_db_partition_stats is really much faster.

    However, it has to be like Forum Newbie done on his example.

    On your example, the record count is resulted with a wrong value.

  • That is what kchant means when he says

    ...if you're confident your database stats are correct...

    If stats aren't updated, sys partitions won't be accurate.

  • It is very true that the numbers may not 100% accurate however it depends very much where you need to use the counts from all tables in a database and for what purpose. Microsoft recommends to run DBCC UPDATEUSAGE for a Databases upgraded from SQL Server 2000 that may contain invalid counts but after that they should be pretty much accurate - see "best practice" under http://msdn.microsoft.com/en-us/library/ms188414.aspx.

    Besides that I believe that when you run such a query against a live database you do not expect 100% accurate counts because if you think: by the time ALL the counts are completed the numbers in some of the tables will be off due to DELETEs and INSERTs that are inevitable in a database. Hope this clarifies my suggestion to use sp_spaceused.

  • In my experience, every table has a row in sys.sysindexes that can be used to tell the number of rows in the table.

    SELECT i.rowcnt, o.name

    FROM sys.sysobjects o JOIN sys.sysindexes i ON i.id = o.id

    WHERE o.xtype = 'U' AND i.indid IN (0, 1)

    ORDER BY o.name

    Because these values are stored in the system tables, this is not an expensive query.

Viewing 11 posts - 1 through 10 (of 10 total)

You must be logged in to reply to this topic. Login to reply