Search This Blog

SQL Server: Does rebuilding clustered index automatically rebuild non clustered indexes

When you have large tables in your database you want to plan maintenance strategically. Its a fine balance that you plan carefully to make sure that you
  • Perform necessary maintenance successfully
  • But not cause any blocking to table access
  • Dependent nonclustered index are rebuilt (if needed) or not rebuild.
What commands does Sql Server provide to facilitate these operations.
Lets take an example:
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
CREATE TABLE dbo.Frag_CI
(
      ID INT NOT NULL IDENTITY(1,1)
    , Frag VARCHAR(800)
)
GO
 
CREATE CLUSTERED INDEX PK_Frag_CI_ID
    ON dbo.Frag_CI (ID ASC)
GO
 
CREATE NONCLUSTERED INDEX IX_Frag_CI_Frag
    ON dbo.Frag_CI (Frag ASC)
GO
 
INSERT INTO dbo.Frag_CI (Frag) VALUES ('1')
GO 1000
Now, let’s check fragmentation. We see that both the clustered and nonclustered indexes are significantly fragmented.
1
2
3
4
5
6
7
8
9
10
11
12
13
14
select    OBJECT_NAME(object_id) AS Table_Name
        , index_type_desc
        , index_depth
        , index_level
        , avg_fragmentation_in_percent
        , fragment_count
        , avg_fragment_size_in_pages
        , page_count
        , avg_page_space_used_in_percent
        , record_count
        , forwarded_record_count
from sys.dm_db_index_physical_stats(db_id(),default,default,default,DEFAULT)
where object_id = object_id('Frag_CI')
GO
CI_nCI_Rebuild_Before
CI_nCI_Rebuild_Before

Solution

Option 1 :

Rebuild the table, resulting in rebuilding both CI and nCI together.
1
ALTER INDEX ALL ON dbo.Frag_CI REBUILD
Above code allows us to rebuild all the indexes on the table at the same time while applying all the options available to reduce the duration of overall rebuild time i.e. MAXDOP, ALLOW_PAGE_LOCKS, etc
CI_nCI_Rebuild
CI_nCI_Rebuild

Option 2:

Here we rebuild the table, using ALTER TABLE command, but surprisingly it only rebuilds the clustered index and does not touch the nonclustered indexes. Interesting to see the difference in behavior between ALTER TABLE….REBUILD ALTER INDEX…REBUILD. Also, there is no ALL keyword option for ALTER TABLE. (Please note that PARTITION=ALL  only affects the partitions selected to rebuildwith in the CI).
1
ALTER TABLE dbo.Frag_CI REBUILD
CI_Rebuild_no_nCI
CI_Rebuild_no_nCI

Option 3:

In this, we rebuild the index using "CREATE INDEX...WITH DROP_EXISTING" option. As expected, this only rebuilds clustered index (nonclustered index is not rebuilt).
In a clustered and non-clustered index setup, clustering key is present in the leaf pages of the nonoclustered index. So, when CI is rebuilt, clustering key does not change, so there is no need to rebuild nCI.
1
2
3
4
CREATE CLUSTERED INDEX PK_Frag_CI_ID
 ON dbo.Frag_CI (ID ASC)
 WITH (DROP_EXISTING = ON)
 GO
CI_Rebuild_no_nCI
CI_Rebuild_no_nCI
Hope this helps,