Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Poor query plan generated for SQL Server 2014 CTP2 clustered columnstore index Expand / Collapse
Author
Message
Posted Monday, November 11, 2013 12:17 PM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Friday, July 18, 2014 7:51 AM
Points: 30, Visits: 450
I posted this on Microsoft's SQL Server forum but I want to post it here as well to see if anyone has ran into this either in SQL 2012 nonclustered columnstore or SQL 2014 clustered columnstore

http://social.msdn.microsoft.com/Forums/sqlserver/en-US/1138262c-b382-4208-aaa3-d5df76df5ee2/poor-query-plan-generated-for-sql-server-2014-clustered-columnstore-index?forum=sql14db

We are testing with clustered columnstore indexes on SQL 2014 CTP2 in our data warehouse to see how its performance stacks up compared to traditional rowstore type tables. However, we ran into a problem with one of the commonly used queries right away as it performed much worse compared to a traditional rowstore table. I was also able to replicate the issue using AdventureWorksDW2012. The database is using 2014 compatibility level.


For the test, I created a new clustered columnstore table, dbo.FactProductInventoryCS, and built a clustered columnstore index for it

select *
into dbo.FactProductInventoryCS
from dbo.FactProductInventory
go
CREATE CLUSTERED COLUMNSTORE INDEX [FactProductInventoryCS_CLCSI] ON [dbo].[FactProductInventoryCS] WITH (DROP_EXISTING = OFF) ON [PRIMARY]
GO

go

Then I ran the following queries against the AdventureWorksDW2012 database, one against the traditional rowstore and the other against the clustered columnstore. The query itself is a very simple star join to DimDate and DimProduct, getting the UnitsBalance for a single day per product

set statistics io, time on

select dp.EnglishProductName, sum(f.UnitsBalance)
from FactProductInventory f
inner join DimDate dd on f.DateKey = dd.DateKey
inner join DimProduct dp on f.ProductKey = dp.ProductKey
where dd.FullDateAlternateKey = '2008-12-31'
group by dp.EnglishProductName


select dp.EnglishProductName, sum(f.UnitsBalance)
from FactProductInventoryCS f
inner join DimDate dd on f.DateKey = dd.DateKey
inner join DimProduct dp on f.ProductKey = dp.ProductKey
where dd.FullDateAlternateKey = '2008-12-31'
group by dp.EnglishProductName

Here's the output for set statistics. notice the clustered columnstore took 6 times as long to finish. Even though both queries finished in practically no time, my real-world fact table with a 100 million+ records significantly magnifies this problem (e.g. from 10 seconds to 1 minute)

(504 row(s) affected)
Table 'FactProductInventory'. Scan count 0, logical reads 1864, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.
Table 'DimProduct'. Scan count 1, logical reads 477, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.
Table 'DimDate'. Scan count 0, logical reads 2, 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 = 0 ms, elapsed time = 14 ms.

(504 row(s) affected)
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.
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 'DimProduct'. Scan count 1, logical reads 477, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.
Table 'FactProductInventoryCS'. Scan count 1, logical reads 379, physical reads 0, read-ahead reads 12, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.
Table 'DimDate'. Scan count 0, logical reads 2, 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 = 78 ms, elapsed time = 84 ms.
SQL Server parse and compile time:
CPU time = 0 ms, elapsed time = 0 ms.

SQL Server Execution Times:
CPU time = 0 ms, elapsed time = 0 ms.

I can't upload the query plan here either but you will see that for the rowstore it's able to do a seek predicate on the date key in 1 execution, whereas for the clustered columnstore it would do a row mode select against the fact table then do a filter on the date in separate executions.

I've read many blog posts where people are saying the query optimizer has improved significantly for batch processing support in many types of queries, but this is a very standard inner join fact to dimension query with a date filter so I didn't expect this query to perform as poorly as it did, especially in my real world test case where the query would go from 10 seconds or so in traditional rowstore to 1 minute, since the size of the data is much bigger.
Post #1513217
Posted Thursday, November 14, 2013 8:47 PM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Friday, July 18, 2014 7:51 AM
Points: 30, Visits: 450
For those who are interested, this is the connect item submitted to MS

https://connect.microsoft.com/SQLServer/feedback/details/808566/poor-query-plan-generated-for-sql-server-2014-clustered-columnstore-index

Their feedback was to lower the cost threshold for parallelism but this did not work for both the AdventureWorks test case as well as for the real world test case with 69+ million records
Post #1514570
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse