sp_TableCounts
This is another secret weapon in my SSMS Query Shortcuts series. Sometimes the simple things are what we need to deliver best results as consultants. So if it is simple– we better be able to nail it on command when that client or manager is looking over your shoulder.
The faster, better way to get table row counts (and sizes)
SELECT COUNT(*) FROM SomeBigTable;
The tried and true way to get a rowcount. Also probably the worst way. Not that it is always a problem… but that is, in part, part of the problem. Exactly because it is not always an issue it can throw you off when it does cause one. Or worse, it hangs up production, blocking important stuff, while you’re off doing something else meantime. Sure, a NOLOCK may help and even a OPTION (MAXDOP 48) but there is still a better way and sp_TableCounts keeps it right at your fingertips.
[thrive_lead_lock id=’660′]
USE [master] GO IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'sp_TableCounts') and OBJECTPROPERTY(id, N'IsProcedure') = 1) DROP PROC sp_TableCounts GO /*========================================================================================================= Procedure: sp_TableCounts ========================================================================================================== DESCRIPTION: A quick way to get to table row counts and size stats. It works best as a query shortcut. For more insight visit: https://jamesbond.consulting/sp_TableCounts PROVIDED BY: James Bond Consulting (JBC) Written by: James Bond (c) 2019, https://jamesbond.consulting. All rights reserved. email: [email protected] You may alter this script (the "Software") for your own in-house purposes. You may also republish or blog code including without limitation the rights to use, copy, modify, merge, distribute, sublicense, and/or sell copies of the Software, and to permit persons to whom the Software is furnished to do so, subject to the following conditions: § The above copyright notice and this permission notice shall be included in all copies or substantial portions of the Software. THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE. =============================================================================================================*/ CREATE PROCEDURE sp_TableCounts @String VARCHAR(1000) = NULL AS DECLARE @SQLString NVARCHAR(MAX), @ParmDefinition NVARCHAR(500), @db SYSNAME = db_name() SET @string = LTRIM(RTRIM(REPLACE(REPLACE(@string,'[',''),']',''))); SET @SQLString = N' WITH cIndexes AS ( SELECT OBJECT_SCHEMA_NAME(ps.object_id) + ''.''+ OBJECT_NAME(ps.object_id) AS TableName, i.name aS IndexName, i.type_desc as IndexType, SUM(ps.row_count) AS [Row_Count], SUM(ps.in_row_reserved_page_count) * 8 / 1024 AS [In_row_reserved_page_count (MB)], SUM(ps.lob_reserved_page_count) * 8 / 1024 AS [LOB_reserved_page_count (MB)], SUM(ps.row_overflow_reserved_page_count) * 8 / 1024 AS [Row_overflow_reserved_page_count (MB)], SUM(ps.reserved_page_count) * 8 / 1024 AS [Reserved_page_count (MB)] FROM sys.dm_db_partition_stats ps JOIN sys.indexes i ON i.object_id = ps.object_id AND i.index_id = ps.index_id WHERE (@string IS NULL OR @String = CASE WHEN @String LIKE ''%.%'' THEN OBJECT_SCHEMA_NAME(ps.object_id) +''.'' ELSE '''' END + OBJECT_NAME(ps.object_id)) --AND i.type_desc IN (''HEAP'',''CLUSTERED'') GROUP BY ps.object_id,i.name,i.type_desc) SELECT TableName, IndexName, IndexType, FORMAT([Row_Count],''N0'') AS [Row_Count], FORMAT([In_row_reserved_page_count (MB)],''N0'') AS [In_row_reserved_page_count (MB)], FORMAT([LOB_reserved_page_count (MB)],''N0'') AS [LOB_reserved_page_count (MB)], FORMAT([Row_overflow_reserved_page_count (MB)],''N0'') AS [Row_overflow_reserved_page_count (MB)], FORMAT([Reserved_page_count (MB)],''N0'') AS [Reserved_page_count (MB)] FROM cIndexes UNION SELECT TableName, ''TOTAL SUMMARY'', ''SUM OF SIZE'', NULL, FORMAT(SUM([In_row_reserved_page_count (MB)]),''N0''), FORMAT(SUM([LOB_reserved_page_count (MB)]),''N0''), FORMAT(SUM([Row_overflow_reserved_page_count (MB)]),''N0''), FORMAT(SUM([Reserved_page_count (MB)]),''N0'') FROM cIndexes GROUP BY TableName ORDER BY 1,IndexType'; SET @ParmDefinition = N'@String NVARCHAR(1000)'; --SELECT @SQLString, @String EXECUTE sp_executesql @SQLString, @ParmDefinition, @String = @String;
[/thrive_lead_lock]