SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Table row count using 3 different ways


Table row count using 3 different ways

Author
Message
Mohit Nayyar
Mohit Nayyar
SSC Veteran
SSC Veteran (286 reputation)SSC Veteran (286 reputation)SSC Veteran (286 reputation)SSC Veteran (286 reputation)SSC Veteran (286 reputation)SSC Veteran (286 reputation)SSC Veteran (286 reputation)SSC Veteran (286 reputation)

Group: General Forum Members
Points: 286 Visits: 94
Comments posted to this topic are about the item Table row count using 3 different ways

Thanks
Mohit Nayyar
http://mohitnayyar.blogspot.com/
"If I am destined to fail, then I do have a purpose in my life, To fail my destiny"
ianhenderson
ianhenderson
SSC-Enthusiastic
SSC-Enthusiastic (101 reputation)SSC-Enthusiastic (101 reputation)SSC-Enthusiastic (101 reputation)SSC-Enthusiastic (101 reputation)SSC-Enthusiastic (101 reputation)SSC-Enthusiastic (101 reputation)SSC-Enthusiastic (101 reputation)SSC-Enthusiastic (101 reputation)

Group: General Forum Members
Points: 101 Visits: 34
I've always found cursors a really slow way of doing pretty much anything in SQL, to say nothing of being a horror to code if it's big enough.

There could be a fourth way. Create a temporary table containing the name and object_id values of every user table in the database. Then create a loop to do the following:

a. Select the name of the table object with the lowest object_id value;
b. Execute a string of dynamic SQL to count the number of rows in the table bearing the name that you retrieved in step 1;
c. Delete the record in the temporary table that you've just been looking at;
d. Repeat until the temporary table is empty;

You could refine it further by writing the result of the count into a new table (temporary or otherwise). Or even by adding an additional column to the original temporary table and then updating that each time. The only difference is that you wouldn't delete the record once you'd finished with it, merely select the minimum object_id value as long as it was higher than the object_id value you'd just finished with.

Just a thought :-)
dchappell-903283
dchappell-903283
Mr or Mrs. 500
Mr or Mrs. 500 (509 reputation)Mr or Mrs. 500 (509 reputation)Mr or Mrs. 500 (509 reputation)Mr or Mrs. 500 (509 reputation)Mr or Mrs. 500 (509 reputation)Mr or Mrs. 500 (509 reputation)Mr or Mrs. 500 (509 reputation)Mr or Mrs. 500 (509 reputation)

Group: General Forum Members
Points: 509 Visits: 74
To expand on ianhenderson's way here is the loop without worrying about the lowest id and just grabbing the next one that doesn't have a count.

DECLARE @TableName VARCHAR(255);

SELECT TABLE_NAME AS TableName, null AS RowCnt
INTO #TempTableCounts
FROM INFORMATION_SCHEMA.TABLES
WHERE TABLE_TYPE = 'base table';

WHILE (EXISTS(SELECT * FROM #TempTableCounts WHERE (RowCnt IS NULL))) BEGIN
SELECT TOP(1) @TableName = TableName FROM #tempTableCounts WHERE (RowCnt IS NULL);
EXEC ('UPDATE #TempTableCounts SET RowCnt = (SELECT count(*) FROM ' + @TableName + ') WHERE (TableName = ''' + @TableName + ''')');
END

SELECT TableName, RowCnt FROM #TempTableCounts;

DROP TABLE #TempTableCounts;



-David
ron.mcdowell
ron.mcdowell
SSC Rookie
SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)

Group: General Forum Members
Points: 26 Visits: 706
Does this seemingly simpler, and far faster, method produce accurate results?



SELECT name [Table], sum(row_count) AS [Rows]
FROM sys.dm_db_partition_stats WITH (NOLOCK), sysobjects WITH (NOLOCK)
WHERE index_id < 2 -- Just grab index 0 (heap) or 1 (cluster)
AND xtype = 'U'
AND object_id = object_id('' + name + '')
GROUP BY name



ianhenderson
ianhenderson
SSC-Enthusiastic
SSC-Enthusiastic (101 reputation)SSC-Enthusiastic (101 reputation)SSC-Enthusiastic (101 reputation)SSC-Enthusiastic (101 reputation)SSC-Enthusiastic (101 reputation)SSC-Enthusiastic (101 reputation)SSC-Enthusiastic (101 reputation)SSC-Enthusiastic (101 reputation)

Group: General Forum Members
Points: 101 Visits: 34
Nice to see I started a healthy debate! I'm going to bear this stuff in mind - I'm always looking for smarter-running code!
dchappell-903283
dchappell-903283
Mr or Mrs. 500
Mr or Mrs. 500 (509 reputation)Mr or Mrs. 500 (509 reputation)Mr or Mrs. 500 (509 reputation)Mr or Mrs. 500 (509 reputation)Mr or Mrs. 500 (509 reputation)Mr or Mrs. 500 (509 reputation)Mr or Mrs. 500 (509 reputation)Mr or Mrs. 500 (509 reputation)

Group: General Forum Members
Points: 509 Visits: 74
ron.mcdowell that is an awesome script. My initial testing shows it is significantly faster than my script and for all my tests it was accurate. Now I need to learn how/why it works :-)

-David
Iwas Bornready
Iwas Bornready
SSC-Insane
SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)SSC-Insane (22K reputation)

Group: General Forum Members
Points: 22058 Visits: 885
Thanks for the script.
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search