Code to list index counts per table

Yesterday I blogged about how having too few or too many nonclustered indexes can be a big problem for performance (see here). Today I’m posting some code you can run which will print out the number of indexes for each table in each database on an instance.

I made it print a result set per database so the table in msdb doesn’t get too big having to store schema and object names. You can get the code below and here: NCIndexCounts.zip (870.00 bytes).

I also created a version that *does* store names and prints a single result set. You can get that one here: NCIndexCountsSingleResultSet.zip (1.41 kb).

There’s probably a niftier way to do this but I’m not a T-SQL expert :-)

Enjoy!

/*============================================================================
File:     NCIndexCounts.sql

  Summary:  Nonclustered index counts (multiple result sets)

  SQL Server Versions: 2005 onwards
------------------------------------------------------------------------------
Written by Paul S. Randal, SQLskills.com

  (c) 2011, SQLskills.com. All rights reserved.

For more scripts and sample code, check out https://www.SQLskills.com

You may alter this code for your own *non-commercial* purposes. You may
republish altered code as long as you include this copyright and give due
credit, but you must obtain prior permission before blogging this code.

THIS CODE AND INFORMATION ARE PROVIDED "AS IS" WITHOUT WARRANTY OF
ANY KIND, EITHER EXPRESSED OR IMPLIED, INCLUDING BUT NOT LIMITED
TO THE IMPLIED WARRANTIES OF MERCHANTABILITY AND/OR FITNESS FOR A
PARTICULAR PURPOSE.
============================================================================*/

IF EXISTS (SELECT * FROM msdb.sys.objects WHERE [name] = 'SQLskillsPaulsIndexCounts')
DROP TABLE msdb.dbo.SQLskillsPaulsIndexCounts;
GO
CREATE TABLE msdb.dbo.SQLskillsPaulsIndexCounts (
SchemaID INT,
ObjectID INT,
BaseType CHAR (10),
IndexCount SMALLINT);
GO

EXEC sp_MSforeachdb
N'IF EXISTS (SELECT 1 FROM (SELECT DISTINCT [name]
FROM sys.databases WHERE [state_desc] = ''ONLINE''
AND [database_id] > 4
AND [name] != ''pubs''
AND [name] != ''Northwind''
AND [name] != ''distribution''
AND [name] NOT LIKE ''ReportServer%''
AND [name] NOT LIKE ''Adventure%'') AS names WHERE [name] = ''?'')
BEGIN
USE [?]
INSERT INTO msdb.dbo.SQLskillsPaulsIndexCounts
SELECT o.[schema_id], o.[object_id], ''Heap'', 0
FROM sys.objects o
WHERE o.[type_desc] IN (''USER_TABLE'', ''VIEW'')
AND o.[is_ms_shipped] = 0
AND EXISTS (
SELECT *
FROM sys.indexes
WHERE [index_id] = 0
AND [object_id] = o.[object_id]);

INSERT INTO msdb.dbo.SQLskillsPaulsIndexCounts
SELECT o.[schema_id], o.[object_id], ''Clustered'', 0
FROM sys.objects o
WHERE o.[type_desc] IN (''USER_TABLE'', ''VIEW'')
AND o.[is_ms_shipped] = 0
AND EXISTS (
SELECT *
FROM sys.indexes
WHERE [index_id] = 1
AND [object_id] = o.[object_id]);

UPDATE msdb.dbo.SQLskillsPaulsIndexCounts
SET [IndexCount] = (
SELECT COUNT (*)
FROM sys.indexes i
WHERE i.object_id = [ObjectID]
AND i.[is_hypothetical] = 0)

IF EXISTS (SELECT * FROM msdb.dbo.SQLskillsPaulsIndexCounts)
SELECT
''?'' AS [Database],
SCHEMA_NAME ([SchemaID]) AS [Schema],
OBJECT_NAME ([ObjectID]) AS [Table],
[BaseType],
(CASE
WHEN [IndexCount] = 0 THEN 0
ELSE [IndexCount]-1 END)
AS [NCIndexes]
FROM msdb.dbo.SQLskillsPaulsIndexCounts
ORDER BY [BaseType] DESC, IndexCount;

TRUNCATE TABLE msdb.dbo.SQLskillsPaulsIndexCounts;
END';
GO

DROP TABLE msdb.dbo.SQLskillsPaulsIndexCounts;
GO

6 thoughts on “Code to list index counts per table

  1. For the lucky ones on CS servers!

    SET [IndexCount] = (
    SELECT COUNT (*)
    FROM sys.indexes i
    WHERE i.object_id = [ObjectID]
    AND i.[is_hypothetical] = 0)

  2. Hi, I’m not a DBA, I’m a Network Engineer/Server Manager/whatever is needed today. I’m trying to help improve the performance and utilization of RAM on one of our database servers, and doing some analysis. I’ve tried for about 30 minutes or so but feel I’m missing some basic knowledge of how to reference a table by a variable name, in my attempt to add a column to this output that shows the COUNT in the table named Table. I gave up and started doing it by hand one at a time but there’re a lot more tables than I thought there’d be when I started this. My question – rather, my request, is that someone tell me where to paste a quick line or two in here thtat just appends the existing dataset row with a record count? Not lazy just out of time, thanks in advance!

  3. I am trying to run the code and get the following errors. Msg 102, Level 15, State 1, Line 36
    Incorrect syntax near ‘;’.

Leave a Reply

Your email address will not be published. Required fields are marked *

Other articles

Imagine feeling confident enough to handle whatever your database throws at you.

With training and consulting from SQLskills, you’ll be able to solve big problems, elevate your team’s capacity, and take control of your data career.