Vous êtes ici :
Ce script permet d’estimer la compression pour toutes les tables et index de la base courante.
Source : Paul Nielsen (www. SQLServerBible.com)
Transact-SQL
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 |
-- Estimates the row and page compression gain for every object and index in the database -- Paul Nielsen -- www.SQLServerBible.com -- March 13, 2008 -- to do: -- [ ] transaction error from insert...Exec sp_estimate_data_compression_savings -- [ ] filter objects to only those eligible for compression 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 ); CREATE TABLE #dbEstimate ( PK INT IDENTITY NOT NULL PRIMARY KEY , 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 ); INSERT INTO #dbEstimate ( schema_name , object_name , index_id , ixName , ixType , partition_number , data_compression_desc ) SELECT S.name , O.name , I.index_id , I.name , I.type_desc , P.partition_number , P.data_compression_desc FROM sys.schemas AS S JOIN sys.objects AS O ON S.schema_id = O.schema_id JOIN sys.indexes AS I ON O.object_id = I.object_id JOIN sys.partitions AS P ON I.object_id = P.object_id AND I.index_id = P.index_id WHERE O.type = 'U'; -- Determine Compression Estimates DECLARE @PK INT , @Schema VARCHAR(150) , @object VARCHAR(150) , @DAD VARCHAR(25) , @partNO INT , @indexID INT , @SQL NVARCHAR(MAX); DECLARE cCompress CURSOR FAST_FORWARD FOR SELECT schema_name , object_name , index_id , partition_number , data_compression_desc FROM #dbEstimate; OPEN cCompress; FETCH cCompress INTO @Schema , @object , @indexID , @partNO , @DAD; -- prime the cursor WHILE @@Fetch_Status = 0 BEGIN IF @DAD = 'NONE' BEGIN -- estimate Page compression 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'; UPDATE #dbEstimate SET None_Size = O.size_with_current_compression_setting , Page_Size = O.size_with_requested_compression_setting FROM #dbEstimate 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 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'; UPDATE #dbEstimate SET Row_Size = O.size_with_requested_compression_setting FROM #dbEstimate 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; -- none compression estimate IF @DAD = 'ROW' BEGIN -- estimate Page compression 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'; UPDATE #dbEstimate SET Row_Size = O.size_with_current_compression_setting , Page_Size = O.size_with_requested_compression_setting FROM #dbEstimate 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 None compression 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 = 'none'; UPDATE #dbEstimate SET None_Size = O.size_with_requested_compression_setting FROM #dbEstimate 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; -- row compression estimate IF @DAD = 'PAGE' BEGIN -- estimate Row compression 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'; UPDATE #dbEstimate SET Page_Size = O.size_with_current_compression_setting , Row_Size = O.size_with_requested_compression_setting FROM #dbEstimate 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 None compression 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 = 'NONE'; UPDATE #dbEstimate SET None_Size = O.size_with_requested_compression_setting FROM #dbEstimate 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; -- page compression estimate FETCH cCompress INTO @Schema , @object , @indexID , @partNO , @DAD; END; CLOSE cCompress; DEALLOCATE cCompress; -- report findings SELECT schema_name + '.' + object_name AS [Object] , index_id , ixName , ixType , partition_number , data_compression_desc AS Current_Compression , CAST(( 1 - ( CAST(Row_Size AS FLOAT) / None_Size )) * 100 AS INT) AS RowGain , CAST(( 1 - ( CAST(Page_Size AS FLOAT) / None_Size )) * 100 AS INT) AS PageGain , CASE WHEN ( 1 - ( CAST(Row_Size AS FLOAT) / None_Size )) >= .25 AND ( Row_Size <= Page_Size ) THEN 'Row' WHEN ( 1 - ( CAST(Page_Size AS FLOAT) / None_Size )) >= .25 AND ( Page_Size <= Row_Size ) THEN 'Page' ELSE 'None' END AS Recommended_Compression FROM #dbEstimate WHERE None_Size <> 0 ORDER BY [Object]; |
Table of Contents