SQL Server Index Internals and How Filtered Indexes Look Like (Part 2)

In the first part of this series, I talked about how SQL Server navigates thru the index structure and used a clustered index as an example to demonstrate how the process works. To continue this series, we’ll look at filtered indexes and how they look like from a storage perspective.

If you look at the non-clustered index definitions, the only difference between the two is the inclusion of a WHERE clause. Now, if the WHERE clause returns just a subset of the entire table, we can expect a smaller storage requirement for a filtered index. Let’s take a look at the size of the index using the T-SQL query below.

USE SampleDB
GO
SELECT
OBJECT_NAME(i.OBJECT_ID) AS TableName,
i.name AS IndexName,
i.index_id AS IndexID,
8 * SUM(a.used_pages) AS 'Indexsize(KB)'
FROM sys.indexes AS i
JOIN sys.partitions AS p ON p.OBJECT_ID = i.OBJECT_ID AND p.index_id = i.index_id
JOIN sys.allocation_units AS a ON a.container_id = p.partition_id
WHERE OBJECT_NAME(i.OBJECT_ID) ='SalesOrderDetail'
GROUP BY i.OBJECT_ID,i.index_id,i.name

Looking at the screenshot, my guess is that the entire table contains half of the records that have a ModifiedDate greater than 2004-01-01. Let’s use DBCC IND and DBCC PAGE – similar to what we did with the clustered index – to analyze the contents of the filtered index. This time, we’ll use IndexID value 3, the index ID of the filtered index.

DBCC IND (SampleDB, SalesOrderDetail, 3)

I’ve already sorted out the index levels and found out that the page with the highest level is page number 880. Let’s use DBCC PAGE this time to navigate thru the index pages.

DBCC TRACEON (3604)
GO
DBCC PAGE (SampleDB, 1, 880, 3)

If you look closely, all of the index pages have a ModifiedDate greater than 2004-01-01. Compare this with the non-clustered index without the WHERE clause where the index pages contain all of the ModifiedDate values – a value for each record in the table.

DBCC PAGE (SampleDB, 1, 248, 3)

With fewer pages to navigate thru, it will be faster to run a query that references the ModifiedDate column.

Side Note: While working on this blog post, I stumbled upon a bug that got me spinning around in circles trying to figure out if there was something wrong with what I was doing. I did the usual thing of using DBCC IND and DBCC PAGE to navigate the index structure. However, I couldn’t get the tabular result to display when both the filtered and non-filtered indexes exist on the database. It took me a while to figure out that it was the filtered index that caused DBCC PAGE to not display the tabular result. I asked the question on the internal SQL Server MVP mailing list before I found out about this Connect item. Apparently, DBCC PAGE does not return a tabular result for the non-leaf level pages when a filtered index exists on a database. You will experience this behavior when running DBCC PAGE on a SQL Server 2012 instance. All the sample code that I used for these blog posts were on SQL Server 2008 R2 instance.

Please note: I reserve the right to delete comments that are offensive or off-topic.

Leave a Reply

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