Performance plays a vital role in SQL server. The importance of performance increases with the rise in the data growth. In other words, increase in data growth is directly proportional to the increase in performance. In SQL Server, index plays an important role to increase the performance as well. In SQL server 2012, we got a boost in performance (a new type of index came) namely ColumnStore Index. It is one of the nicest database features introduced in SQL Server 2012 built on xVelocity technology which is used to optimize memory. Lets discuss its syntax , purpose, examples & performance.
Syntax:
CREATE [ NONCLUSTERED ] COLUMNSTORE INDEX index_name
ON ( column [ ,…n ] )
[ WITH ( [ ,…n ] ) ]
[ ON {
{ partition_scheme_name ( column_name ) }
| filegroup_name
| “default”
}
]
[ ; ]
::=
{
[database_name. [schema_name ] . | schema_name . ]
table_name
{
::=
{
DROP_EXISTING = { ON | OFF }
| MAXDOP = max_degree_of_parallelism
}
Purpose :
The purpose of ColumnStore Index is to increase the performance in comparison to the traditional Index. It is a number of times faster than traditional index. The reason behind its performance is the way it handles the index. In Tradition Index, it stores multiple rows in each page and it retrieves in the same way. In ColumnStore Index, it stores each column in separate page and it retrieves in the same way.
In simple words you can say Tradition Index is a Row store while ColumnStore Index is a Column store.
Graphical Representation:
Given below is the graphical representation of traditional index & ColumnStore Index and you can see how each technology keeps the data pages in a different manner.
Let’s test the performance of ColumnStore index Step by Step.
Step 1 :
Create a sample table.
CREATE TABLE dbo.[PurchaseOrderDetail_Sample]( [PurchaseOrderID] [int] NOT NULL, [PurchaseOrderDetailID] [int] NOT NULL, [DueDate] [datetime] NOT NULL, [OrderQty] [smallint] NOT NULL, [ProductID] [int] NOT NULL, [UnitPrice] [money] NOT NULL, [LineTotal] numeric(18,2), [ReceivedQty] [decimal](8, 2) NOT NULL, [RejectedQty] [decimal](8, 2) NOT NULL, [StockedQty] Numeric(18,2), [ModifiedDate] [datetime] NOT NULL)
Step 2 :
Insert some data into table (PurchaseOrderDetail_Sample), because if table has few records you cannot measure the performance of columnstore index properly.
--This insertion is just to demonstrate, --It is not recommended on production server. Insert into dbo.[PurchaseOrderDetail_Sample] Select * from [Purchasing].[PurchaseOrderDetail] GO 100
Step 3 :
Next step is to create a Columnstore index in this table.
CREATE NONCLUSTERED COLUMNSTORE INDEX [IX_PurchaseOrderDetail_Sample_ColumnStore] ON [PurchaseOrderDetail_Sample] (UnitPrice, OrderQty,ReceivedQty,ProductID) GO
Step 4 :
Now, it is time to create a query using this table and view the performance. Remember this query has a ColumnStore Index.
SET STATISTICS TIME ON SET STATISTICS IO ON --This query will use columnstore index and will return the result set. SELECT ProductID as [Product ID], AVG(UnitPrice) as [Average Unit Price] ,SUM(OrderQty) as [Purchase Order Qty], AVG(ReceivedQty) as [Received Qty] FROM [dbo].[PurchaseOrderDetail_Sample] GROUP BY ProductID ORDER BY ProductID go --This query will ignore columnstore index and will return the result set. SELECT ProductID as [Product ID], AVG(UnitPrice) as [Average Unit Price] ,SUM(OrderQty) as [Purchase Order Qty], AVG(ReceivedQty) as [Received Qty] FROM [dbo].[PurchaseOrderDetail_Sample] GROUP BY ProductID ORDER BY ProductID OPTION (IGNORE_NONCLUSTERED_COLUMNSTORE_INDEX) SET STATISTICS TIME OFF SET STATISTICS IO OFF
Step 5 :
Lets compare the result of IO & Time Statistics for both, with columnstore index and without columnstore index.
Type |
Logical Reads |
CPU Time |
Elapsed Time |
ColumnStore |
34 |
47 ms |
342 ms |
Without ColumnStore |
8345 |
1482 ms |
1473 ms |
Execution Plan comparison :
Conclusion :
I am quite impressed to see the performance of Columnstore index. It is very handy and recommended in a place where you are either facing performance issues with the query or dealing with data warehouse. However, Columnstore index has some limitations as well which I will post in my upcoming post.
[…] days ago, I was working on a client database and faced some issues with ColumnStore index and to fix those issue I had to develop certain tools. Given below is the list of tools I developed […]
[…] Statement failed because data cannot be updated in a table with a columnstore index. Consider disabling the columnstore index before issuing the statement, then rebuilding the columnstore index after S_MSG is complete is one of the new error messages shipped with SQL Server 2012 and related to columnstore index. […]
[…] days ago, I was working on columnstore Index and I came across a problem finding the size of all columnstore Indexes […]
[…] when I was working on Columnstore index and I came across this error, CREATE INDEX statement failed. Column ‘%.*ls’has a data […]
[…] Columnstore index is one of the nice features introduced in SQL Server 2012. It improves the performance more times than the normal query but on the other hand it has some limitations as well, and one of the limitation is that you cannot create a CLUSTERED Columnstore index. […]
Interesting post. I think your comparison would be a little more valuable if you put a couple of other indexes on the table. For example I put the following nonclustered index on the table:
CREATE NONCLUSTERED INDEX [IX_PurchaseOrderDetail_Sample_ProductId_Inc] ON [dbo].[PurchaseOrderDetail_Sample]
(
[ProductID] ASC
)
INCLUDE ( [OrderQty],
[UnitPrice],
[ReceivedQty])
Using your same queries I found that I had to put an index hint to force the use of the columnstore index otherwise the query optimizer used the nonclustered index instead. However the columnstore index did indeed speed the query and reduce the number of logical io.
using nonclustered index
(265 row(s) affected)
Table ‘PurchaseOrderDetail_Sample’. Scan count 1, logical reads 4066, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.
(1 row(s) affected)
SQL Server Execution Times:
CPU time = 828 ms, elapsed time = 1249 ms.
using columnstore index
(265 row(s) affected)
Table ‘PurchaseOrderDetail_Sample’. Scan count 4, logical reads 208, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.
Table ‘Worktable’. Scan count 0, logical reads 0, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.
Table ‘Workfile’. Scan count 0, logical reads 0, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.
(1 row(s) affected)
SQL Server Execution Times:
CPU time = 32 ms, elapsed time = 158 ms.
Thanks for doing the article.
Hi John,
Thanks for the valuable addition.
Imran
[…] Columnstore index is one of the new features shipped with SQL Server 2012. I have written few articles about this type of index and described how it boosts in the performance. Recently, I worked on a huge table having table partitions residing in different file groups. And it seems that it is already optimized using Table partition. However, I tried to create a columnstore Index to further boost its performance and I did succeed. […]
[…] https://raresql.com/2013/03/17/sql-server-2012-columnstore-index/ […]