Dela via


Creating Compressed Tables and Indexes

SQL Server 2008 supports both row and page compression for both tables and indexes. Data compression can be configured for the following database objects:

  • A whole table that is stored as a heap.

  • A whole table that is stored as a clustered index.

  • A whole nonclustered index.

  • A whole indexed view.

  • For partitioned tables and indexes, the compression option can be configured for each partition, and the various partitions of an object do not have to have the same compression setting.

The compression setting of a table is not automatically applied to its nonclustered indexes. Each index must be set individually. Compression is not available for system tables. Tables and indexes can be compressed when they are created by using the CREATE TABLE and CREATE INDEX statements. To change the compression state of a table, index, or partition, use the ALTER TABLE or ALTER INDEX statements.

Note

If the existing data is fragmented, you might be able to reduce the size of the index by rebuilding the index instead of using compression. The fill factor of an index will be applied during an index rebuild, which could potentially increase the size of the index. For more information, see Fill Factor.

Considerations for When You Use Row and Page Compression

When you use row and page compression, be aware the following considerations:

  • Compression is available only in the SQL Server 2008 Enterprise and Developer editions.

  • Compression can allow more rows to be stored on a page, but does not change the maximum row size of a table or index.

  • A table cannot be enabled for compression when the maximum row size plus the compression overhead exceeds the maximum row size of 8060 bytes. For example, a table that has the columns c1 char(8000) and c2 char(53) cannot be compressed because of the additional compression overhead. When the vardecimal storage format is used, the row-size check is performed when the format is enabled. For row and page compression, the row-size check is performed when the object is initially compressed, and then checked as each row is inserted or modified. Compression enforces the following two rules:

    • An update to a fixed-length type must always succeed.

    • Disabling data compression must always succeed. Even if the compressed row fits on the page, which means that it is less than 8060 bytes; SQL Server prevents updates that would not fit on the row when it is uncompressed.

  • When a list of partitions is specified, the compression type can be set to ROW, PAGE, or NONE on individual partitions. If the list of partitions is not specified, all partitions are set with the data compression property that is specified in the statement. When a table or index is created, data compression is set to NONE unless otherwise specified. When a table is modified, the existing compression is preserved unless otherwise specified.

  • If you specify a list of partitions or a partition that is out of range, an error will be generated.

  • Nonclustered indexes do not inherit the compression property of the table. To compress indexes, you must explicitly set the compression property of the indexes. By default, the compression setting for indexes will set to NONE when the index is created.

  • When a clustered index is created on a heap, the clustered index inherits the compression state of the heap unless an alternative compression state is specified.

  • When a heap is configured for page-level compression, pages receive page-level compression only in the following ways:

    • Data is bulk imported with bulk optimizations enabled.

    • Data is inserted using INSERT INTO ... WITH (TABLOCK) syntax.

    • A table is rebuilt by executing the ALTER TABLE ... REBUILD statement with the PAGE compression option.

  • New pages allocated in a heap as part of DML operations will not use PAGE compression until the heap is rebuilt. Rebuild the heap by removing and reapplying compression, or by creating and removing a clustered index.

  • Changing the compression setting of a heap requires all nonclustered indexes on the table to be rebuilt so that they have pointers to the new row locations in the heap.

  • You can enable or disable ROW or PAGE compression online or offline. Enabling compression on a heap is single threaded for an online operation.

  • The disk space requirements for enabling or disabling row or page compression are the same as for creating or rebuilding an index. For partitioned data, you can reduce the space that is required by enabling or disabling compression for one partition at a time.

  • To determine the compression state of partitions in a partitioned table, query the data_compression column of the sys.partitions catalog view.

  • When you are compressing indexes, leaf-level pages can be compressed with both row and page compression. Non–leaf-level pages do not receive page compression.

  • Because of their size, large-value data types are sometimes stored separately from the normal row data on special purpose pages. Data compression is not available for the data that is stored separately.

  • Tables which implemented the vardecimal storage format in SQL Server 2005 will retain that setting when upgraded. You can apply row compression to a table that has the vardecimal storage format. However, because row compression is a superset of the vardecimal storage format, there is no reason to retain the vardecimal storage format. Decimal values gain no additional compression when you combine the vardecimal storage format with row compression. You can apply page compression to a table that has the vardecimal storage format; however, the vardecimal storage format columns probably will not achieve additional compression.

    Note

    SQL Server 2008 supports the vardecimal storage format; however, because row-level compression achieves the same goals, the vardecimal storage format is deprecated. This feature will be removed in a future version of Microsoft SQL Server. Avoid using this feature in new development work, and plan to modify applications that currently use this feature.

Compression Implementation

For a summary of the implementation of data compression, see Row Compression Implementation, Page Compression Implementation, and Unicode Compression Implementation.

Estimating Compression Savings

To determine how changing the compression state will affect a table or an index, use the sp_estimate_data_compression_savings stored procedure. The sp_estimate_data_compression_savings stored procedure is available only in the editions of SQL Server that support data compression.

How Compression Affects Partitioned Tables and Indexes

When you are using data compression with partitioned tables and indexes, be aware of the following considerations:

  • Splitting a range

    When partitions are split by using the ALTER PARTITION statement, both partitions inherit the data compression attribute of the original partition.

  • Merging a range

    When two partitions are merged, the resultant partition inherits the data compression attribute of the destination partition.

  • Switching partitions

    To switch a partition, the data compression property of the partition must match the compression property of the table.

  • Rebuilding one partition or all partitions

    There are two syntax variations that you can use to modify the compression of a partitioned table or index:

    • The following syntax rebuilds only the referenced partition:

      ALTER TABLE <table_name> 
      REBUILD PARTITION = 1 WITH (DATA_COMPRESSION =  <option>)
      
    • The following syntax rebuilds the whole table by using the existing compression setting for any partitions that are not referenced:

      ALTER TABLE <table_name> 
      REBUILD PARTITION = ALL 
      WITH (DATA_COMPRESSION = PAGE ON PARTITIONS(<range>),
      ... )
      

    Partitioned indexes follow the same principle using ALTER INDEX.

  • Dropping a partitioned clustered index

    When a clustered index is dropped, the corresponding heap partitions retain their data compression setting unless the partitioning scheme is modified. If the partitioning scheme is changed, all partitions are rebuilt to an uncompressed state. To drop a clustered index and change the partitioning scheme requires the following steps:

    1. Drop the clustered index.

    2. Modify the table by using the ALTER TABLE ... REBUILD ... option that specifies the compression option.

    To drop a clustered index OFFLINE is a very fast operation, because only the upper levels of clustered indexes are removed. When a clustered index is dropped ONLINE, SQL Server must rebuild the heap two times, once for step 1 and once for step 2.

How Compression Affects Replication

When you are using data compression with replication, be aware of the following considerations:

  • When the Snapshot Agent generates the initial schema script, the new schema will use the same compression settings for both the table and its indexes. Compression cannot be enabled on just the table and not the index.

  • For transactional replication the article schema option determines what dependent objects and properties have to be scripted. For more information, see sp_addarticle.

    The Distribution Agent does not check for down-level Subscribers when it applies scripts. If the replication of compression is selected, creating the table on down-level Subscribers will fail. In the case of a mixed topology, do not enable the replication of compression.

  • For merge replication, publication compatibility level overrides the schema options and determines the schema objects that will be scripted. For more information about compatibility level, see Using Multiple Versions of SQL Server in a Replication Topology.

    In the case of a mixed topology, if it is not required to support the new compression options, the publication compatibility level should be set to the down-level Subscriber version. If it is required, compress tables on the Subscriber after they have been created.

The following table shows replication settings that control compression during replication.

User intent

Replicate partition scheme for a table or index

Replicate compression settings

Scripting behavior

To replicate the partition scheme and enable compression on the Subscriber on the partition.

True

True

Scripts both the partition scheme and the compression settings.

To replicate the partition scheme but not compress the data on the Subscriber.

True

False

Scripts out the partition scheme but not the compression settings for the partition.

To not replicate the partition scheme and not compress the data on the Subscriber.

False

False

Does not script partition or compression settings.

To compress the table on the Subscriber if all the partitions are compressed on the Publisher, but not replicate the partition scheme.

False

True

Checks if all the partitions are enabled for compression.

Scripts out compression at the table level.

How Compression Affects Other SQL Server Components

Compression occurs in the storage engine and the data is presented to most of the other components of SQL Server in an uncompressed state. This limits the effects of compression on the other components to the following:

  • Bulk import and export operations

    When data is exported, even in native format, the data is output in the uncompressed row format. This can cause the size of exported data file to be significantly larger than the source data.

    When data is imported, if the target table has been enabled for compression, the data is converted by the storage engine into compressed row format. This can cause increased CPU usage compared to when data is imported into an uncompressed table.

    When data is bulk imported into a heap with page compression, the bulk import operation will try to compress the data with page compression when the data is inserted.

  • Compression does not affect backup and restore.

  • Compression does not affect log shipping.

  • Data compression is incompatible with sparse columns. Therefore, tables containing sparse columns cannot be compressed nor can sparse columns be added to a compressed table.

  • Enabling compression can cause query plans to change because the data is stored using a different number of pages and number of rows per page.

  • Data compression is supported by SQL Server Management Studio through the Data Compression Wizard.

To start the Data Compression Wizard

  • In Object Explorer, right-click a table, index, or indexed view, point to Storage, and then click Compress.

Monitoring Compression

To monitor compression of the whole instance of SQL Server, use the Page compression attempts/sec and Pages compressed/sec counters of the SQL Server, Access Methods Object.

To obtain page compression statistics for individual partitions, query the sys.dm_db_index_operational_stats dynamic management function.

Examples

Some of the following examples use partitioned tables and require a database that has filegroups. To create a database that has filegroups, execute the following statement.

CREATE DATABASE TestDatabase
ON  PRIMARY
( NAME = TestDatabase,
    FILENAME = 'C:\Program Files\Microsoft SQL Server\MSSQL10_50.MSSQLSERVER\MSSQL\Data\TestDB.mdf'),
FILEGROUP test1fg
( NAME = TestDBFile1,
    FILENAME = 'C:\Program Files\Microsoft SQL Server\MSSQL10_50.MSSQLSERVER\MSSQL\Data\TestDBFile1.mdf'),
FILEGROUP test2fg
( NAME = TestDBFile2,
    FILENAME = 'C:\Program Files\Microsoft SQL Server\MSSQL10_50.MSSQLSERVER\MSSQL\Data\TestDBFile2.ndf'),
FILEGROUP test3fg
( NAME = TestDBFile3,
    FILENAME = 'C:\Program Files\Microsoft SQL Server\MSSQL10_50.MSSQLSERVER\MSSQL\Data\TestDBFile3.ndf'),
FILEGROUP test4fg
( NAME = TestDBFile4,
    FILENAME = 'C:\Program Files\Microsoft SQL Server\MSSQL10_50.MSSQLSERVER\MSSQL\Data\TestDBFile4.ndf') ;
GO

To switch to the new database:

USE TestDatabase
GO

A. Creating a table that uses row compression

The following example creates a table and sets the compression to ROW.

CREATE TABLE T1 
(c1 int, c2 nvarchar(50) )
WITH (DATA_COMPRESSION = ROW);
GO

B. Creating a table that uses page compression

The following example create a table and sets the compression to PAGE.

CREATE TABLE T2 
(c1 int, c2 nvarchar(50) )
WITH (DATA_COMPRESSION = PAGE);
GO

C. Setting the DATA_COMPRESSION option on a partitioned table

The following example uses the TestDatabase table that is created by using the code provided earlier in this section. The example creates a partition function and scheme, and then creates a partitioned table and specifies the compression options for the partitions of the table. In this example, partition 1 is configured for ROW compression, and the remaining partitions are configured for PAGE compression.

To create a partition function:

CREATE PARTITION FUNCTION myRangePF1 (int)
AS RANGE LEFT FOR VALUES (1, 100, 1000) ;
GO

To create a partition scheme:

CREATE PARTITION SCHEME myRangePS1
AS PARTITION myRangePF1
TO (test1fg, test2fg, test3fg, test4fg) ;
GO

To create a partitioned table that has compressed partitions:

CREATE TABLE PartitionTable1 
(col1 int, col2 varchar(max))
ON myRangePS1 (col1) 
WITH 
(
  DATA_COMPRESSION = ROW ON PARTITIONS (1),
  DATA_COMPRESSION = PAGE ON PARTITIONS (2 TO 4)
);
GO

D. Setting the DATA_COMPRESSION option on a partitioned table

The following example uses the database that is used in example C. The example creates a table by using the syntax for noncontiguous partitions.

CREATE TABLE PartitionTable2 
(col1 int, col2 varchar(max))
ON myRangePS1 (col1) 
WITH 
(
  DATA_COMPRESSION = ROW ON PARTITIONS (1,3),
  DATA_COMPRESSION = NONE ON PARTITIONS (2,4)
);
GO

E. Modifying a table to change the compression

The following example changes the compression of the nonpartitioned table that is created in example A.

ALTER TABLE T1 
REBUILD WITH (DATA_COMPRESSION = PAGE);
GO

F. Modifying the compression of one partition in a partitioned table

The following example changes the compression of the partitioned table that is created in example C. The REBUILD PARTITION = 1 syntax causes only partition number 1 to be rebuilt.

ALTER TABLE PartitionTable1 
REBUILD PARTITION = 1 WITH (DATA_COMPRESSION =  NONE) ;
GO

The same operation that uses the following alternate syntax causes all partitions in the table to be rebuilt.

ALTER TABLE PartitionTable1 
REBUILD PARTITION = ALL 
WITH (DATA_COMPRESSION = PAGE ON PARTITIONS(1) ) ;
GO

G. Modifying the compression of a several partitions in a partitioned table

The REBUILD PARTITION = ... syntax can rebuild only one partition. To rebuild more than one partition, you must execute multiple statements, or execute the following example to rebuild all partitions, using the current compression settings for unspecified partitions.

ALTER TABLE PartitionTable1 
REBUILD PARTITION = ALL 
WITH
(
DATA_COMPRESSION = PAGE ON PARTITIONS(1), 
DATA_COMPRESSION = ROW ON PARTITIONS(2 TO 4) 
) ;
GO

H. Modifying the compression on an index

The following example uses the table that is created in example A and creates an index on the column C2.

CREATE NONCLUSTERED INDEX IX_INDEX_1 
    ON T1 (C2) 
WITH ( DATA_COMPRESSION = ROW ) ; 
GO

Execute the following code to change the index to page compression:

ALTER INDEX IX_INDEX_1 
ON T1
REBUILD WITH ( DATA_COMPRESSION = PAGE ) ;
GO

I. Modifying the compression of a single partition in a partitioned index

The following example creates an index on a partitioned table that uses row compression on all partitions of the index.

CREATE CLUSTERED INDEX IX_PartTab2Col1
ON PartitionTable1 (Col1)
WITH ( DATA_COMPRESSION = ROW ) ;
GO

To create the index so that is uses different compression settings for different partitions, use the ON PARTITIONS syntax. The following example creates an index on a partitioned table that uses row compression on partition 1 of the index and page compression on partitions 2 through 4 of the index.

CREATE CLUSTERED INDEX IX_PartTab2Col1
ON PartitionTable1 (Col1)
WITH (DATA_COMPRESSION = ROW ON PARTITIONS(1),
    DATA_COMPRESSION = PAGE ON PARTITIONS (2 TO 4 ) ) ;
GO

The following example changes the compression of the partitioned index.

ALTER INDEX IX_PartTab2Col1 ON PartitionTable1
REBUILD PARTITION = ALL 
WITH ( DATA_COMPRESSION = PAGE ON PARTITIONS(1) ) ;
GO

J. Modifying the compression of a several partitions in a partitioned index

The REBUILD PARTITION = ... syntax can rebuild only one partition. To rebuild more than one partition, you must execute multiple statements, or execute the following example to rebuild all partitions, using the current compression settings for unspecified partitions.

ALTER INDEX IX_PartTab2Col1 ON PartitionTable1
REBUILD PARTITION = ALL 
WITH
(
DATA_COMPRESSION = PAGE ON PARTITIONS(1), 
DATA_COMPRESSION = ROW ON PARTITIONS(2 TO 4) 
) ;
GO