BLOG

Practical Clustered Columnstore Index on Parallel Data Warehouse (part 2)

11.05.2014 Hilmar Buchta

PDW 2012 | APS 2012

In part 1 of this topic, I showed how basic insert operations in a CCI table are handled internally. As we saw, inserting of large batches causes the CCI to compress the data immediately (apart from the remaining rows that are still kept in the delta store) while small batches are causing closed row groups which are compressed asynchronously in the backgroud. Now I like to focus more on insert operations and on the distributions within the CCI table.

 

Step Description
9 What happens for an update-operation on an already compressed row? Let’s try:

  1. update CCITest set val=’Test X‘ where val=’Test del‘

Since the compressed rows in the columnstore cannot be physically updated, the CCI marks the existing row as ‘deleted’ and inserts the new values as a new row. Therefore you see one deleted row (I included that column from the meta data query here) and one new row in the open row group (now containing 51425 rows instead of 51424 before):

image_thumb4

All subsequent update or delete operations to this row are now written to the delta store. Deleted rows cause some kind of fragmentation in the CCI. While one deleted row is nothing to worry about, you should carefully monitor the number of deleted rows in your CCI tables. If you find many deleted rows you should defragment the table using CTAS (as CTAS is always the answer…) or index rebuild. CTAS copies the data over to a new table thus resolving fragmentation. This still does not guarantee that the data is in compressed form after the CTAS. After all, CTAS goes through the delta store mechanism we’ve been discovered before and as we’ve seen, this may result in row groups that are still open and waiting for more rows of data to arrive. The other option for defragmentation of a CCI table is to run an index rebuild:

  1. alter index all on CCITest rebuild partition = 1
  2. — or alternatively: partition=ALL            

One thing to consider is, that this statement requires an exclusive lock on the table. Currently we’re using partition switching to move new data into our fact tables and therefore we’re running index rebuild/reorganize operations before switching the partition into the final fact table.

10 Ok, back to start. How many open, closed, compressed row groups can we have in the CCI table? While we will only find at most one open row group per partition and distribution, we can have as many closed and compressed row groups as needed. Take a look at the following example (starting with a truncate to reset our table):

 

  1. truncate table CCITest
  2. declare @i int =1
  3. while @i<50 begin
  4. insert into CCITest select top 100000 1, ‚Test‘ from MyLargeTable
  5. set @i=@i+1
  6. end

Immediately after the statement is executed the result from the meta data query will look like this:

clip_image00121_thumb2

Since we inserted in small batches, the open row group is used until it reaches the limit of 1,048,576 rows. After that, it is closed and a new open row group is created.

Again, after a while, the tuple mover process begins picking up the closed row groups. The following screenshot was taken while the tuple mover still processes the table:

clip_image0023_thumb2

And finally, when the tuple mover is finished, the closed row groups are all compressed:

clip_image0033_thumb2

11 Now let’s try something different. As I said before, row groups are created per distribution and partition. Now we’re going to perform 16 inserts on a 2 compute node appliance (each with 8 distributions thus giving 16 distributions in total). I adjusted the id (hash column) in a way that we’re hitting all of the 16 distributions:

 

  1. truncate table CCITest
  2. insert into CCITest select top 100000 0, ‚Test‘ from MyLargeTable
  3. insert into CCITest select top 100000 1, ‚Test‘ from MyLargeTable
  4. insert into CCITest select top 100000 2, ‚Test‘ from MyLargeTable
  5. insert into CCITest select top 100000 3, ‚Test‘ from MyLargeTable
  6. insert into CCITest select top 100000 4, ‚Test‘ from MyLargeTable
  7. insert into CCITest select top 100000 5, ‚Test‘ from MyLargeTable
  8. insert into CCITest select top 100000 6, ‚Test‘ from MyLargeTable
  9. insert into CCITest select top 100000 7, ‚Test‘ from MyLargeTable
  10. insert into CCITest select top 100000 8, ‚Test‘ from MyLargeTable
  11. insert into CCITest select top 100000 9, ‚Test‘ from MyLargeTable
  12. insert into CCITest select top 100000 10, ‚Test‘ from MyLargeTable
  13. insert into CCITest select top 100000 11, ‚Test‘ from MyLargeTable
  14. insert into CCITest select top 100000 12, ‚Test‘ from MyLargeTable
  15. insert into CCITest select top 100000 13, ‚Test‘ from MyLargeTable
  16. insert into CCITest select top 100000 14, ‚Test‘ from MyLargeTable
  17. insert into CCITest select top 100000 15, ‚Test‘ from MyLargeTable

As you see, for each distribution a new row group in status ‘open’ is created.

clip_image00123_thumb3

Think about this for a moment. Since we already showed that we can load about 1 million rows in an open row group (as long as we’re using small batches of up to 100,000 rows) and could have about 16 million rows in open row groups (one million per distribution) per partition as a worst case.

So, if you’re using CCI on smaller tables (for example a dimension table) or on tables with many partitions, you can easily face situations, where most of the table’s rows are uncompressed. Again, it’s important to monitor the amount of uncompressed rows and to perform an alter index reorganize (for the closed row groups) or alter index rebuild (if there are too many open row groups).

12 Speaking about monitoring. A good start is the meta data query from above. However, you could also try running dbcc pdw_showspaceused. Let’s try:

 

  1. dbcc pdw_showspaceused(CCITest)

What you can see here is, that dbcc pdw_showspaceused does only count compressed rows (first column reads 0 rows in each of the 16 distributions). Therefore, pdw_showspaceused is not a good tool for determining uncompressed rows in a CCI table.

clip_image002_thumb3

13 After running an index rebuild on the table, dbcc pdw_showspaceused shows the correct number of rows since all rows are now stored in compressed row groups:

 

  1. alter index all on CCITest rebuild partition = 1
  2. dbcc pdw_showspaceused(CCITest)

clip_image0026_thumb2

Summary

CCI is a powerful feature in the PDW 2012 appliance. However, you should monitor your CCI tables carefully for open/closed row groups, because the data in such row groups is not yet compressed and depending on the table layout (for example the number of partitions) you may find a lot of rows here. Maintenance tasks (index reorganize, index rebuild) or a smart loading strategy (for example by performing the rebuild before the partition with the new data is switched into the final table) are counter measures to consider here. If your CCI table also has to handle delete or update operations you may also have to deal with fragmentation (number of deleted rows in the CCI). Consider using CTAS and partition switching patterns rather than running delete or update statements that involve a lot of rows. If this is not possible, monitoring fragmentation is important. Then, from time to time, you will have to defragment the CCI table (CTAS each partition to a new table or use index rebuild).

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

Join #teamoraylispeople

Gestalte mit uns
die Welt der Daten