다음을 통해 공유


Maintaining Uniqueness with Clustered ColumnStore Index | SQL Server 2014

Column Store indexes were introduced in SQL Server 2012 with a flavor of Non-Clustered index i.e.  “Non-Clustered ColumnStore” index. However there is a big limitation that the underlying table becomes read-only as soon as you create one.

In SQL Server 2014 this behavior is unchanged and addition to this you can also create ColumnStore index as a Clustered index. And the good thing is that the table having “Clustered ColumnStore” index can also be updated. However there is one more big limitation here that there is no Clustered Key with this type if index, thus risking the Uniqueness in the table.

–>  Here we will see this limitation and a workaround which can be used in some scenarios:

USE tempdb

GO

 

-- Create a simple table with 3 columns having 1st column to contain Unique values:

CREATETABLEdbo.TableWithCCI

(

    `` PKCol ``intNOTNULL``,

    `` Foo ``int``,

    `` Bar ``int

)

GO

 

-- Now create a "Clustered ColumnStore" index on this table:

CREATE CLUSTERED COLUMNSTORE ``INDEX CCI_TableWithCCI ``ONdbo.TableWithCCI

GO

–> Notice:  While creating this index there is no provision to provided the “Clustering Key”, as this index includes all of the columns in the table, and stores the entire table by compressing the data and store by column.

On checking the metadata (by ALT+F1) of the table, you will see NULL under the index_keyscolumn:

SQLServer2014_Unique_CCI

Now let’s check this feature of absence of Uniquenes. We will enter 2 records with same value:

insertintodbo.TableWithCCI

select1,2,3

 

insertintodbo.TableWithCCI

select1,22,33

GO

 

SELECT * ``FROMdbo.TableWithCCI

GO

You will see 2 records with same duplicate value.

Now, let’s create another Unique index to enforce this constraint:

CREATEUNIQUEINDEX UX_TableWithCCI ``ONdbo.TableWithCCI(PKCol)

GO

We get an error that you cannot create more indexes if you have a Clustered ColumnStore index:

Msg 35303, Level 16, State 1, Line 25
CREATE INDEX statement failed because a nonclustered index cannot be created on a table that has a clustered columnstore index. Consider replacing the clustered columnstore index with a nonclustered columnstore index.

–> Workaround:  As a workaround we can create an Indexed/Materialized View on top this table, with Clustering Key as the PK (1st column of the table/view):

CREATEVIEW dbo.vwTableWithCCI

    ``WITHSCHEMABINDING

AS

    ``SELECTPKCol, Foo, Bar

    ``FROMdbo.TableWithCCI

GO

 

-- Delete duplicate records entered previously:

DELETEFROMdbo.TableWithCCI

GO

 

-- Create a Unique Clustered Index on top of the View to Materialize it:

CREATEUNIQUE CLUSTERED ``INDEX IDX_vwTableWithCCI ``ONdbo.vwTableWithCCI(PKCol)

GO

Now let’s try to enter duplicate records again and see if these can be entered or not:

insertintodbo.TableWithCCI

select1,2,3

 

insertintodbo.TableWithCCI

select1,22,33

GO

Now, as expected we get an error after we inserted 1st records and tried to insert the 2nd duplicate record:

(1 row(s) affected)
Msg 2601, Level 14, State 1, Line 48
Cannot insert duplicate key row in object ‘dbo.vwTableWithCCI’ with unique index ‘IDX_vwTableWithCCI’. The duplicate key value is (1).
The statement has been terminated.

While using this workaround you need to consider this approach if possible. Like in some scenarios where the table is very big and there are frequent updates (INSERT/UPDATE/DELETES) this approach of maintaining another Indexed-View would be expensive. So this approach should be evaluated before implementing.

-- Final Cleanup:

DROPVIEWdbo.vwTableWithCCI

GO

DROPTABLEdbo.TableWithCCI

GO

You can also refer to MSDN BOL  [here]  for checking all limitations with ColumnStore Indexes.

Source: from my personal blog SQLwithManoj: https://sqlwithmanoj.com/2014/07/24/maintaining-uniqueness-with-clustered-columnstore-index-sql-server-2014/