Hi Friends,
In Columnstore Technology, we knows that Column data stores in segments and segments groups together to form the rowgroup. One of the main reason of using Columnstore technology is compression of rowgroups. By default, SQL Server perform compression of closed delta stores. This tasks is done by tuple mover. Which invokes after a fixed time interval. Tuple mover searches for closed delta store and perform compression over that delta store.
Compression is itself a resource consuming operation. We can disable this behaviour of tuple mover by using trace flag 634.
First we will see the default behaviour of SQL Server (Here I am using SQL Server 2014 and AdventureWorksDW database):
USE [AdventureWorksDW2014]; GO CREATE TABLE [dbo].[FactInternetSales_Copy] ( [SalesOrderNumber] [nvarchar](20) NOT NULL, [SalesAmount] [money] NOT NULL, [CarrierTrackingNumber] [nvarchar](25) NULL, [CustomerPONumber] [nvarchar](25) NULL, [OrderDate] [datetime] NULL, [DueDate] [datetime] NULL, [ShipDate] [datetime] NULL ) ON [PRIMARY] GO CREATE CLUSTERED COLUMNSTORE INDEX CCI_FactInternetSales_Copy ON [AdventureWorksDW2014].[dbo].[FactInternetSales_Copy] GO INSERT INTO [AdventureWorksDW2014].[dbo].[FactInternetSales_Copy] SELECT [SalesOrderNumber] ,[SalesAmount] ,[CarrierTrackingNumber] ,[CustomerPONumber] ,[OrderDate] ,[DueDate] ,[ShipDate] FROM [AdventureWorksDW2014].[dbo].[FactInternetSales] GO 20 Select OBJECT_NAME(object_id) as TableName, row_group_id, delta_store_hobt_id, State_description, total_rows from sys.column_store_row_groups
You can see that there are two delta stores, one is closed and another is open. Closed delta store will be converted into compressed whenever tuple mover will be invoked. Execute below T-SQL statement after 5-6 minutes:
USE [AdventureWorksDW2014]; GO Select OBJECT_NAME(object_id) as TableName, row_group_id, delta_store_hobt_id, State_description, total_rows from sys.column_store_row_groups
In above output, you can see that Closed delta store has been converted into compressed state. This task is done by tuple mover. If required, we can disable this behaviour of tuple mover by using trace flag 634.
USE [Master]; GO DBCC TRACEON(634,-1) GO USE [AdventureWorksDW2014]; GO INSERT INTO [AdventureWorksDW2014].[dbo].[FactInternetSales_Copy] SELECT [SalesOrderNumber] ,[SalesAmount] ,[CarrierTrackingNumber] ,[CustomerPONumber] ,[OrderDate] ,[DueDate] ,[ShipDate] FROM [AdventureWorksDW2014].[dbo].[FactInternetSales] GO 20 Select OBJECT_NAME(object_id) as TableName, row_group_id, delta_store_hobt_id, State_description, total_rows from sys.column_store_row_groups
We have inserted more rows into the table. Status of row-group id 1 has been changed to closed. This delta store will not be converted to compressed by tuple mover because we are using trace flag 634. If we will check the status again after 5-6 minutes it should not be changed.
If you wants to compress closed delta store then you can reorganize the Columnstore index:
USE [AdventureWorksDW2014] GO ALTER INDEX [CCI_FactInternetSales_Copy] ON [dbo].[FactInternetSales_Copy] REORGANIZE WITH ( LOB_COMPACTION = ON ) GO Select OBJECT_NAME(object_id) as TableName, row_group_id, delta_store_hobt_id, State_description, total_rows from sys.column_store_row_groups
If you wants to compress the open state delta store then you have to specify Compress_All_Row_Groups=ON with Reorganize.
USE [AdventureWorksDW2014] GO ALTER INDEX [CCI_FactInternetSales_Copy] ON [dbo].[FactInternetSales_Copy] REORGANIZE WITH (COMPRESS_ALL_ROW_GROUPS = ON); GO Select OBJECT_NAME(object_id) as TableName, row_group_id, delta_store_hobt_id, State_description, total_rows from sys.column_store_row_groups
USE [Master] GO DBCC TRACEOFF(634,-1)
PS: Do not use trace flags in production environment without testing it on non-production environments and without consulting because everything comes at a cost.
HAPPY LEARNING!
Thanks & Regards:
Prince Rastogi
Like us on FaceBook | Join the fastest growing SQL Server group on FaceBook
Follow Prince Rastogi on Twitter | Follow Prince Rastogi on FaceBook