Enabling Data Compression – October 2013 Update

Note: For more details about this script and the variables and outputs, see my post here.

I’ve made two changes to my script that checks for new database objects to compress. First, it will now enclose table and index names in square brackets to prevent errors with object names that are also keywords or include dashes (such as Sharepoint databases). I also added some code to handle situations where a table or index might have been scanned initially, but by the time the procedure got around to performing the compression, that object had been deleted. (Because the script is designed to be run over multiple days, a system that creates and deletes tables on a regular basis may run into this situation.) I also fixed a bug where the scan to determine the compression estimates was not limited to only the database specified. This was causing some objects to be incorrectly tagged as no longer existing.

As always, don’t run any code from the internet unless you understand what it is doing. Let me know if you have any other suggestions for improvements.


CREATE PROC [dbo].[up_CompressDatabase]
      (
       @minCompression FLOAT = .25 /* e.g. .25 for minimum of 25% compression */
      ,@MaxRunTimeInMinutes INT = 60
      ,@ExecuteCompressCommand BIT = 0	/* 1 to execute command */
      ,@DBToScan SYSNAME /* database to compress */
      )
AS
      SET nocount ON;

/*
	Original script by Paul Nielsen www.SQLServerBible.com March 13, 2008
	Modified by Shaun J. Stuart www.shaunjstuart.com February 27, 2013

  Sets compression for all objects and indexes in the database needing adjustment
  If estimated gain is equal to or greater than min compression parameter
    then enables row or page compression, whichever gives greater space savings
  If row and page have same gain then, enables row compression
  If estimated gain is less than min compression parameter, then compression is set to none

  - SJS 2/27/13
  - Added @MaxRunTimeInMinutes to limit run length (checked afer each command, so
		may run longer) Note: This timer only applies to the actual compression process.
		It does not limit the time it takes to perform a scan of all the tables / indexes
		and estimate compression savings.
  - Sorted compression cursor to compress smallest tables first
  - Added flag to execute compression command or not
  - Added sort in tempdb option (always)
  - Re-wrote slightly to persist initial scan results. Will only re-scan after all tables
		have been processed

	- SJS 7/17/13
	- Modified to only look at data that is not already compressed
	- Modified for that any items with null none_size, page_size, or row_size are no longer set as
		AlreadyProcessed and now have their sizes calculated (i.e. if process was cancelled before
		initial scan was completed)
	- Modified so that time limit now applies to compression estimate process as well as actual
		compression process
	- Only look at partitions that have at least one row

	- SJS 8/6/13
	- Changed name of dbEstimate table to dbCompressionEstimates for clarity
	- Added StatusText column to dbCompressionEstimates and added status messages
	- Modified to take database name as input parameter to allow use in utility database
		instead of the DB being compressed (Table dbCompressionEstimates, which stores sizes and
		compression estimates, is still created in the current database.)
	- Note: Compression estimates are only made for the database supplied as an input
		parameter. However, that database name is stored in the dbCompressionEstimates table and
		will be read from there and used when actually performing the compression. This allows you to
		create estimates only for multiple databases (using @ExecuteCompressCommand=0), then perform
		the compression	across multiple databases later (with @ExecuteCompressCommand=1).
	- Removed all references to code that checked already compressed data since this routine now only
		looks at uncompressed data.

	- SJS 8/21/13
	- Put []s around table and index names in compression commands.

	- SJS 10/7/13
	- Added check to make sure table / index still exists before estimating or performing compression.
	- Fixed bug in cursor to determine compression estimates (left out db name in where clause)

*/

      IF ISNULL(@DBToScan, '') NOT IN (SELECT   [name]
                                       FROM     sys.databases)
         BEGIN
               SELECT   'Database ' + ISNULL(@DBToScan, 'NULL')
                        + ' not found on server.'
               RETURN
         END

      DECLARE @CompressedCount INT;
      SET @CompressedCount = 0;

      DECLARE @SQL NVARCHAR(MAX);
      DECLARE @ParmDefinition NVARCHAR(100);
      DECLARE @TestResult NVARCHAR(20);
      DECLARE @CheckString NVARCHAR(1000);

      DECLARE @StartTime DATETIME2;
      SET @StartTime = CURRENT_TIMESTAMP;

      DECLARE @CurrentDatabase SYSNAME;
      SET @CurrentDatabase = DB_NAME()

      IF OBJECT_ID('tempdb..##ObjEst', 'U') IS NOT NULL
         DROP TABLE ##ObjEst

      CREATE TABLE ##ObjEst
             (
              PK INT IDENTITY
                     NOT NULL
                     PRIMARY KEY
             ,object_name VARCHAR(250)
             ,schema_name VARCHAR(250)
             ,index_id INT
             ,partition_number INT
             ,size_with_current_compression_setting BIGINT
             ,size_with_requested_compression_setting BIGINT
             ,sample_size_with_current_compression_setting BIGINT
             ,sample_size_with_requested_compresison_setting BIGINT
             );

      IF NOT EXISTS ( SELECT    1
                      FROM      sys.objects
                      WHERE     object_id = OBJECT_ID(N'[dbo].[dbCompressionEstimates]')
                                AND type IN (N'U') )
         BEGIN
               CREATE TABLE dbo.dbCompressionEstimates
                      (
                       PK INT IDENTITY
                              NOT NULL
                              PRIMARY KEY
                      ,DatabaseName SYSNAME
                      ,schema_name VARCHAR(250)
                      ,object_name VARCHAR(250)
                      ,index_id INT
                      ,ixName VARCHAR(255)
                      ,ixType VARCHAR(50)
                      ,partition_number INT
                      ,data_compression_desc VARCHAR(50)
                      ,None_Size INT
                      ,Row_Size INT
                      ,Page_Size INT
                      ,AlreadyProcessed BIT
                      ,StatusText VARCHAR(75)
                      );
         END

  /*
 If all objects have been processed, rescan and start fresh. Useful for catching
  added objects since last scan. But beware - this is I/O intensive and can take a while.
*/

      IF NOT EXISTS ( SELECT    1
                      FROM      dbo.dbCompressionEstimates
                      WHERE     AlreadyProcessed = 0
                                AND DatabaseName = @DBToScan )
         BEGIN
               DELETE   FROM dbo.dbCompressionEstimates
               WHERE    DatabaseName = @DBToScan;

               SET @SQL = 'USE [' + @DBToScan + '];
						INSERT   INTO [' + @CurrentDatabase
                   + '].dbo.dbCompressionEstimates
								(DatabaseName
								,schema_name
								,object_name
								,index_id
								,ixName
								,ixType
								,partition_number
								,data_compression_desc
								,AlreadyProcessed
								,StatusText)
                        SELECT  ''' + @DBToScan + '''
								,S.name
                               ,o.name
                               ,I.index_id
                               ,I.name
                               ,I.type_desc
                               ,P.partition_number
                               ,P.data_compression_desc
                               ,0 AS AlreadyProcessed
							   ,''Initial load'' AS StatusText
                        FROM    [' + @DBToScan + '].sys.schemas AS S
                                JOIN [' + @DBToScan
                   + '].sys.objects AS O ON S.schema_id = O.schema_id
                                JOIN [' + @DBToScan
                   + '].sys.indexes AS I ON o.object_id = I.object_id
                                JOIN [' + @DBToScan
                   + '].sys.partitions AS P ON I.object_id = P.object_id
                                                            AND I.index_id = p.index_id
                        WHERE   O.TYPE = ''U''
                                AND P.data_compression_desc = ''NONE''
								AND P.rows > 0;'		-- only look at objects with data
               EXEC (@SQL)
         END
			-- Determine Compression Estimates
      DECLARE @PK INT
             ,@DatabaseName SYSNAME
             ,@Schema VARCHAR(150)
             ,@object VARCHAR(150)
             ,@DAD VARCHAR(25)
             ,@partNO VARCHAR(3)
             ,@indexID VARCHAR(3)
             ,@ixName VARCHAR(250)
             ,@ixType VARCHAR(50)
             ,@Recommended_Compression VARCHAR(10);

      DECLARE cCompress CURSOR FAST_FORWARD
      FOR
              SELECT    schema_name
                       ,object_name
                       ,index_id
                       ,partition_number
                       ,data_compression_desc
                       ,ixName
              FROM      dbo.dbCompressionEstimates
              WHERE     (None_size IS NULL
                         OR Row_Size IS NULL
                         OR Page_size IS NULL)
                        AND DatabaseName = @DBToScan;

      OPEN cCompress;

      FETCH cCompress INTO @Schema, @object, @indexID, @partNO, @DAD, @ixName;

      WHILE @@Fetch_Status = 0
            BEGIN
							/* evaluate objects with no compression */
                  IF DATEDIFF(mi, @StartTime, CURRENT_TIMESTAMP) < @MaxRunTimeInMinutes
                     BEGIN
							/* First, make sure the table / index still exists (in case this
								process is run over multiple days */

                           IF @indexID = 0
                              BEGIN /* heaps */
                                    SET @CheckString = 'IF object_ID('''
                                        + @DBToScan + '.' + @Schema + '.'
                                        + @object
                                        + ''') IS NULL
									BEGIN
										SELECT @TestResultOUT = ''Does Not Exist''
									END
									ELSE
									BEGIN
										SELECT @TestResultOUT = ''Exists''
									END';
                              END
                           ELSE
                              BEGIN /* indexes */
                                    SET @CheckString = 'IF object_ID('''
                                        + @DBToScan + '.' + @Schema + '.'
                                        + @ixName
                                        + ''') IS NULL
									BEGIN
										SELECT @TestResultOUT = ''Does Not Exist''
									END
									ELSE
									BEGIN
										SELECT @TestResultOUT = ''Exists''
									END';
                              END

                           SET @ParmDefinition = '@TestResultOUT varchar(20) OUTPUT';
                           EXECUTE sp_executesql
                            @CheckString
                           ,@ParmDefinition
                           ,@TestResultOUT = @TestResult OUTPUT;
                           IF @TestResult = 'Exists'
                              BEGIN

                                    IF @DAD = 'none'
                                       BEGIN
									/* estimate Page compression */
                                             SET @SQL = 'USE [' + @DBToScan
                                                 + '];
										INSERT  ##ObjEst
												(object_name
												,schema_name
												,index_id
												,partition_number
												,size_with_current_compression_setting
												,size_with_requested_compression_setting
												,sample_size_with_current_compression_setting
												,sample_size_with_requested_compresison_setting)
												EXEC sp_estimate_data_compression_savings
													@Schema_name = ' + @Schema
                                                 + '
												   ,@object_name = ' + @object
                                                 + '
												   ,@index_id = ' + @indexID
                                                 + '
												   ,@partition_number = '
                                                 + @partNO
                                                 + '
												   ,@data_compression = ''page'';'
                                             EXEC (@SQL)

                                             UPDATE dbo.dbCompressionEstimates
                                             SET    none_size = O.size_with_current_compression_setting
                                                   ,page_size = O.size_with_requested_compression_setting
                                                   ,StatusText = 'Compression estimate 50% complete'
                                             FROM   dbo.dbCompressionEstimates D
                                                    JOIN ##ObjEst O ON D.Schema_name = O.Schema_Name
                                                              AND D.Object_name = O.object_name
                                                              AND D.index_id = O.index_id
                                                              AND D.partition_number = O.partition_number;

                                             DELETE ##ObjEst;

									-- estimate Row compression
                                             SET @SQL = 'USE [' + @DBToScan
                                                 + '];
										INSERT  ##ObjEst
												(object_name
												,schema_name
												,index_id
												,partition_number
												,size_with_current_compression_setting
												,size_with_requested_compression_setting
												,sample_size_with_current_compression_setting
												,sample_size_with_requested_compresison_setting)
												EXEC sp_estimate_data_compression_savings
													@Schema_name = ' + @Schema
                                                 + '
												   ,@object_name = ' + @object
                                                 + '
												   ,@index_id = ' + @indexID
                                                 + '
												   ,@partition_number = '
                                                 + @partNO
                                                 + '
												   ,@data_compression = ''ROW'';'
                                             EXEC (@SQL)

                                             UPDATE dbo.dbCompressionEstimates
                                             SET    row_size = O.size_with_requested_compression_setting
                                                   ,StatusText = 'Compression estimate 100% complete'
                                             FROM   dbo.dbCompressionEstimates D
                                                    JOIN ##ObjEst O ON D.Schema_name = O.Schema_Name
                                                              AND D.Object_name = O.object_name
                                                              AND D.index_id = O.index_id
                                                              AND D.partition_number = O.partition_number;

                                             DELETE ##ObjEst;
                                       END /* end evaluating objects with no compression */
                              END
                           ELSE /* table or index no longer exists */
                              BEGIN
                                    UPDATE  dbo.dbCompressionEstimates
                                    SET     AlreadyProcessed = 1
                                           ,StatusText = 'Object no longer exists at compression estimate stage'
                                    WHERE   schema_name = @Schema
                                            AND object_name = @object
                                            AND index_id = @indexID
                                            AND partition_number = @partNO
                                            AND data_compression_desc = @DAD
                                            AND DatabaseName = @DBToScan;
                              END

                           FETCH NEXT FROM cCompress INTO @Schema, @object,
                                 @indexID, @partNO, @DAD, @ixName
                     END -- end time check block
                  ELSE
                     BEGIN
                           PRINT 'Max runtime reached. No compression performed. Compression estimate still processing. Exiting...';
                           CLOSE cCompress
                           DEALLOCATE cCompress
                           DROP TABLE ##ObjEst
                           RETURN
                     END
            END -- end while loop

      CLOSE cCompress
      DEALLOCATE cCompress

      PRINT 'Initial scan complete.'
         --END
  /* End evaluating compression savings. Now do the actual compressing. */

      PRINT 'Beginning compression.';

  /* Do not process objects that do not meet our compression criteria */

      UPDATE    dbo.dbCompressionEstimates
      SET       AlreadyProcessed = 1
               ,StatusText = 'Best compression method less than minCompression threshold'
      WHERE     (1 - (CAST(Row_Size AS FLOAT) / None_Size)) < @minCompression
                AND (Row_Size <= Page_Size)
                AND None_Size > 0
				AND AlreadyProcessed = 0;

      UPDATE    dbo.dbCompressionEstimates
      SET       AlreadyProcessed = 1
               ,StatusText = 'Best compression method less than minCompression threshold'
      WHERE     (1 - (CAST(Page_Size AS FLOAT) / None_Size)) < @minCompression
                AND (Page_Size <= Row_Size)
                AND None_Size > 0
				AND AlreadyProcessed = 0;

  /* Do not set compression on empty objects */

      UPDATE    dbo.dbCompressionEstimates
      SET       AlreadyProcessed = 1
               ,StatusText = 'No data in table to compress'
      WHERE     None_size = 0
				AND AlreadyProcessed = 0;

 -- set the compression
      DECLARE cCompress CURSOR FAST_FORWARD
      FOR
              SELECT    DatabaseName
                       ,schema_name
                       ,object_name
                       ,partition_number
                       ,ixName
                       ,ixType
                       ,CASE WHEN (1 - (CAST(Row_Size AS FLOAT) / none_Size)) >= @minCompression
                                  AND (Row_Size <= Page_Size) THEN 'Row'
                             WHEN (1 - (CAST(page_Size AS FLOAT) / none_Size)) >= @minCompression
                                  AND (Page_Size <= row_Size) THEN 'Page'
                             ELSE 'None'
                        END AS Recommended_Compression
                       ,PK
              FROM      dbo.dbCompressionEstimates
              WHERE     None_Size <> 0
                        AND (CASE WHEN (1 - (CAST(Row_Size AS FLOAT)
                                             / none_Size)) >= @minCompression
                                       AND (Row_Size <= Page_Size) THEN 'Row'
                                  WHEN (1 - (CAST(page_Size AS FLOAT)
                                             / none_Size)) >= @minCompression
                                       AND (Page_Size <= row_Size) THEN 'Page'
                                  ELSE 'None'
                             END <> data_compression_desc)
                        AND AlreadyProcessed = 0
              ORDER BY  None_Size ASC;		/* start with smallest tables first */

      OPEN cCompress

      FETCH cCompress INTO @DatabaseName, @Schema, @object, @partNO, @ixName,
            @ixType, @Recommended_Compression, @PK  -- prime the cursor;

      WHILE @@Fetch_Status = 0
            BEGIN

                  IF @ixType = 'Clustered'
                     OR @ixType = 'heap'
                     BEGIN
                           SET @SQL = 'USE [' + @DatabaseName + '];
								ALTER TABLE [' + @Schema + '].[' + @object
                               + '] Rebuild with (data_compression = '
                               + @Recommended_Compression
                               + ', SORT_IN_TEMPDB=ON)';

                           SET @CheckString = 'IF object_ID('''
                               + @DatabaseName + '.' + @Schema + '.' + @object
                               + ''') IS NULL
								BEGIN
									SELECT @TestResultOUT = ''Does Not Exist''
								END
								ELSE
								BEGIN
									SELECT @TestResultOUT = ''Exists''
								END';
                     END

                  ELSE
                     BEGIN
                           SET @SQL = 'USE [' + @DatabaseName + '];
								ALTER INDEX [' + @ixName + '] on [' + @Schema
                               + '].[' + @object
                               + '] Rebuild with (data_compression = '
                               + @Recommended_Compression
                               + ',SORT_IN_TEMPDB=ON)';

                           SET @CheckString = 'IF object_ID('''
                               + @DatabaseName + '.' + @Schema + '.' + @ixName
                               + ''') IS NULL
								BEGIN
									SELECT @TestResultOUT = ''Does Not Exist''
								END
								ELSE
								BEGIN
									SELECT @TestResultOUT = ''Exists''
								END';
                     END

                  IF DATEDIFF(mi, @StartTime, CURRENT_TIMESTAMP) < @MaxRunTimeInMinutes
                     BEGIN
                           IF @ExecuteCompressCommand = 1
                              BEGIN

							/* verify that table / index still exists before doing anything */

                                    SET @ParmDefinition = '@TestResultOUT varchar(20) OUTPUT';
                                    EXECUTE sp_executesql
                                        @CheckString
                                       ,@ParmDefinition
                                       ,@TestResultOUT = @TestResult OUTPUT;
                                    IF @TestResult = 'Exists'
                                       BEGIN

                                             UPDATE dbo.dbCompressionEstimates
                                             SET    StatusText = 'Compressing data...'
                                             WHERE  PK = @PK;

                                             PRINT 'Compressing table/index: '
                                                   + @Schema + '.' + @object
                                                   + ' in database '
                                                   + @DatabaseName;
                                             EXEC sp_executesql
                                                @SQL;

                                             UPDATE dbo.dbCompressionEstimates
                                             SET    AlreadyProcessed = 1
                                                   ,StatusText = 'Compression complete'
                                             WHERE  PK = @PK;

                                             SET @CompressedCount = @CompressedCount
                                                 + 1;
                                       END
                                    ELSE
                                       BEGIN
                                             UPDATE dbo.dbCompressionEstimates
                                             SET    AlreadyProcessed = 1
                                                   ,StatusText = 'Object no longer exists at compression stage'
                                             WHERE  PK = @PK;
                                       END
                              END
                           ELSE
                              BEGIN
                                    PRINT 'Command execution not enabled. Command is:'
                                          + @SQL;
                              END
                     END
                  ELSE
                     BEGIN
                           PRINT 'Max runtime reached. Some compression performed. Exiting...';
                           CLOSE cCompress
                           DEALLOCATE cCompress
                           DROP TABLE ##ObjEst
                           BREAK
                     END

                  FETCH cCompress INTO @DatabaseName, @Schema, @object,
                        @partNO, @ixName, @ixType, @Recommended_Compression,
                        @PK;
            END

      CLOSE cCompress;
      DEALLOCATE cCompress;

      PRINT 'Objects compressed: ' + CONVERT(VARCHAR(10), @CompressedCount);
      DROP TABLE ##ObjEst
      RETURN

6 thoughts on “Enabling Data Compression – October 2013 Update

  1. Excellent script, definitely going to be useful for me. I just wanted to point out a slight bug in your logic where you check to see if the index still exists; since nonclustered indexes don’t show up in sys.objects, the check with object_id is always going to return “Does not exist”.

Leave a Reply

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

I am a real person and can prove it by doing this math problem: (required) Time limit is exhausted. Please reload CAPTCHA.

This site uses Akismet to reduce spam. Learn how your comment data is processed.