├── .gitattributes ├── LICENSE ├── README.md ├── cci_maintenance ├── CCI_Reorg_Rebuild_Code.sql └── CCI_Reorg_Rebuild_Tables.sql ├── core └── sp_AgentJobMultiThread.sql └── demo └── ThreadingDemo.sql /.gitattributes: -------------------------------------------------------------------------------- 1 | *.sql linguist-language=TSQL 2 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2020 Joe Obbish 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | Splitting up work to run between multiple SQL Server Agent jobs isn't the easiest thing to do. This framework aims to simplify the process by abstracting away the Agent job parts. Currently only supported for Azure SQL Managed Instances and on-premises SQL Server 2016 SP2+, 2017, and 2019. 2 | 3 | ## core 4 | 5 | You need the core folder to use any of the code in this repository. This folder contains the stored procedures needed for the Agent job multi-threading framework. Key features: 6 | 7 | * All Agent job work is abstracted away with a parent, child, and cleanup stored procedure model 8 | * Can specify the maximum number of child stored procedures that can run at the same time 9 | * The cleanup procedure stops all child procedures if they hit the defined time limit 10 | * The child procedures reschedule themselves in an attempt to spread out work over schedulers evenly 11 | * Validation and error reporting 12 | 13 | ## cci_maintenance 14 | 15 | You want the cci_maintenance folder if you need a clustered columnstore maintenance solution designed to work over very large databases that gives you full control over what maintenance actions happen. You define the priority order for maintenance actions as well as whether or not a partition should go through REORGANIZE or REBUILD. Key features: 16 | 17 | * Can create multiple threads to do work concurrently 18 | * Stops all work at time limit 19 | * Supports columnstore indexes in multiple databases 20 | * Over 40 data points available to define the priority order at the partition level for maintenance actions 21 | * Over 40 data points available to choose between REORGANIZE and REBUILD at the partition level 22 | * Saves history of previous runs which can be used for prioritization 23 | * Queries against sys.dm_db_column_store_row_group_physical_stats run multi-threaded and are skipped if possible 24 | 25 | Note: REORGANIZE and REBUILD do not preserve segment level ordering within a partition. Tables can be excluded from maintenance actions at the schema, table, or table name pattern matching levels. For a maintenance solution that can perserve segment ordering check out [CISL](https://github.com/NikoNeugebauer/CISL). 26 | 27 | Install order: 28 | 29 | 1. Run script in core/sp_AgentJobMultiThread.sql 30 | 2. Create tables in cci_maintenance/CCI_Reorg_Rebuild_Tables.sql 31 | 3. Run script in cci_maintenance/CCI_Reorg_Rebuild_Code.sql 32 | 33 | Example stored procedure call using all default parameter values: 34 | 35 | EXEC [dbo].[CCIReorgAndRebuild] 36 | @CCI_included_database_name_list= N'🔥', -- database list with your CCIs 37 | @max_CCI_alter_job_count = 2, -- number of concurrent jobs that can run 38 | @max_minutes_to_run = 60; -- timeout for all jobs 39 | 40 | 41 | ## demo 42 | 43 | You want the demo folder if you are developing your own code using the framework and think that looking at a simple example would be helpful. This workload runs make-work stored procedures that calculate checksums. 44 | -------------------------------------------------------------------------------- /cci_maintenance/CCI_Reorg_Rebuild_Code.sql: -------------------------------------------------------------------------------- 1 | SET ANSI_NULLS ON; 2 | SET ANSI_PADDING ON; 3 | SET ANSI_WARNINGS ON; 4 | SET ARITHABORT ON; 5 | SET CONCAT_NULL_YIELDS_NULL ON; 6 | SET QUOTED_IDENTIFIER ON; 7 | GO 8 | 9 | -- previous version used sp_ prefix. that was a mistake 10 | DROP PROCEDURE IF EXISTS dbo.sp_CCIReorgAndRebuild; 11 | 12 | GO 13 | 14 | CREATE OR ALTER PROCEDURE [dbo].[CCIReorgAndRebuild] ( 15 | @CCI_included_database_name_list NVARCHAR(4000), 16 | @CCI_excluded_schema_name_list NVARCHAR(4000) = NULL, 17 | @CCI_excluded_table_name_list NVARCHAR(4000) = NULL, 18 | @max_CCI_alter_job_count SMALLINT, 19 | @max_minutes_to_run SMALLINT, 20 | @partition_priority_algorithm_name NVARCHAR(100) = N'DEFAULT', 21 | @SQL_expression_for_partition_priority_calculation NVARCHAR(4000) = NULL, 22 | @rebuild_algorithm_name NVARCHAR(100) = N'NEVER', 23 | @SQL_expression_for_rebuild_calculation NVARCHAR(4000) = NULL, 24 | @ignore_archive_compressed_partitions BIT = 1, 25 | @reorg_use_COMPRESS_ALL_ROWGROUPS_option BIT = 1, 26 | @reorg_execute_twice BIT = 0, 27 | @rebuild_MAXDOP SMALLINT = NULL, 28 | @rebuild_ONLINE_option BIT = 0, 29 | @start_stored_procedure_name_to_run SYSNAME = NULL, 30 | @end_stored_procedure_name_to_run SYSNAME = NULL, 31 | @logging_database_name SYSNAME = NULL, 32 | @logging_schema_name SYSNAME = NULL, 33 | @disable_CPU_rescheduling BIT = 0, 34 | @delimiter_override NVARCHAR(1) = NULL, 35 | @job_prefix_override NVARCHAR(20) = NULL, 36 | @prioritization_only BIT = 0 37 | ) 38 | AS 39 | BEGIN 40 | /* 41 | Procedure Name: CCIReorgAndRebuild 42 | Author: Joe Obbish 43 | Version: 1.0 44 | Updates: https://github.com/jobbish-sql/SQL-Server-Multi-Thread 45 | License: MIT 46 | Purpose: 47 | 48 | A maintenance solution to do ALTER TABLE ... REORGANIZE and REBUILD on clustered columnstore indexes. 49 | Designed to run on large servers against very large databases. 50 | Main features: 51 | * Can create multiple threads to do work concurrently 52 | * Stops all work at time limit 53 | * Supports columnstore indexes in multiple databases 54 | * Over 40 data points available to define the priority order at the partition level for maintenance actions 55 | * Over 40 data points available to choose between REORGANIZE and REBUILD at the partition level 56 | * Saves history of previous runs which can be used for prioritization 57 | * Queries against sys.dm_db_column_store_row_group_physical_stats run multi-threaded and skipped if possible 58 | * Attempts to balance work among schedulers 59 | 60 | 61 | Key Limitations: 62 | * Only runs on SQL Server 2016 SP2+, 2017, and 2019. 63 | * Requires the ability to creates T-SQL Agent Jobs. 64 | * Only performs maintenance actions against clustered columnstore indexes. 65 | * Does not respect segment level ordering within a partition which can be ruined by REORGANIZE and REBUILD. Such tables should be excluded. 66 | * REBUILD is only performable at the partition level instead of at the table level for partitioned tables. 67 | 68 | 69 | Minimum permissions required to run: 70 | * VIEW_SERVER_STATE 71 | * SQLAgentUserRole 72 | * db_datareader on the msdb database 73 | * execute procedure on this database 74 | * db_ddladmin, db_datawriter, db_datareader on the logging schema @logging_schema_name in the logging database @logging_database_name 75 | * db_ddladmin on all databases included in @CCI_included_database_name_list 76 | 77 | WARNING: the @SQL_expression_for_partition_priority_calculation and @SQL_expression_for_rebuild_calculation allow for SQL injection. 78 | This is unavoidable due to what the parameters are used to (passing a SQL expression to be run as part of a more complex query). 79 | If this is unacceptable to you set the @Disable_SQL_Expression_Parameters local variable in this procedure to 1. 80 | 81 | Troubleshooting help: 82 | 83 | This procedure creates T-SQL agent jobs so troubleshooting when something goes wrong can be difficult. 84 | Consider using the @prioritization_only parameter to check everything out before running it for real. 85 | Outside of the T-SQL agent job history, looking at the following tables may be helpful: 86 | 87 | [CCI_Reorg_Rebuild_Summary] - contains one row per run of the maintenance solution 88 | [CCI_Reorg_Rebuild_Index_History] -- contains one row per attempted maintenance action on a partition 89 | [CCI_Reorg_Rebuild_Partitions_To_Process] -- contains one row per CCI partition that haven't had a completed maintenance action for the current run 90 | 91 | 92 | Parameter help: 93 | 94 | @logging_database_name SYSNAME: 95 | 96 | The name of the database that contains all of the tables used by this CCI maintenance solution. 97 | This does not need to match the database that contains all of the stored procedures. 98 | Required procedures: 99 | [CCIReorgAndRebuild] 100 | [CCI_Reorg_Rebuild_Child_Job] 101 | [CCI_Reorg_Rebuild_Cleanup_Jobs] 102 | 103 | Required tables: 104 | [CCI_Reorg_Rebuild_Summary] 105 | [CCI_Reorg_Rebuild_Index_History] 106 | 107 | 108 | @logging_schema_name SYSNAME: 109 | 110 | The schema name that contains all of the tables used by this CCI maintenance solution. 111 | This does not need to match the schema that contains all of the stored procedures. 112 | See documentation for the @logging_database_name parameter. 113 | 114 | 115 | @CCI_included_database_name_list NVARCHAR(4000): 116 | 117 | A list of databases to search for columnstore indexes which could benefit from maintenance operations. 118 | By default, this is comma delimited. 119 | Example usage: "database_1,database_2,database_3". 120 | The delimiter can be changed with the @delimiter_override parameter. 121 | 122 | 123 | @CCI_excluded_schema_name_list NVARCHAR(4000): 124 | 125 | A list of schemas used to exclude columnstore indexes from the search for columnstore indexes 126 | which could benefit from maintenance operations. By default, this is comma delimited. 127 | Example usage: "schema_1,schema_2,schema_3". 128 | The delimiter can be changed with the @delimiter_override parameter. 129 | 130 | 131 | @CCI_excluded_table_name_list NVARCHAR(4000): 132 | 133 | A list of tables used to exclude columnstore indexes from the search for columnstore indexes 134 | which could benefit from maintenance operations. By default, this is comma delimited. 135 | Example usage: "table_1,table_2,table_3". 136 | The delimiter can be changed with the @delimiter_override parameter. 137 | 138 | 139 | @max_CCI_alter_job_count SMALLINT: 140 | 141 | Specify the maximum number of concurrent ALTER INDEX statements that can be run. 142 | This is a required parameter with no default value. Going above the CPU count of the server is not recommended. 143 | One important thing to note is that ALTER INDEX... REORGANIZE by default gets the maximum possible query memory grant. 144 | That means that concurrency may be effectively limited at 3 for systems without TF 6404 or 145 | without Resource Governor limiting the maximum query memory grant. 146 | 147 | 148 | @max_minutes_to_run SMALLINT: 149 | 150 | The maximum number of minutes for the columnstore maintenance solution to run before all jobs are terminated. 151 | 152 | 153 | @partition_priority_algorithm_name NVARCHAR(100): 154 | 155 | Choose the algorithm to prioritize the order of index maintenance operations against columnstore indexes. Choices are: 156 | 157 | DEFAULT - uses the default algorithm set in this procedure. This may change over time. Current logic: 158 | A) ignore any partition with less than 1000 rows 159 | B) first process partitions with deleted + closed + open >= 100000 in order of percentage fragmentation DESC 160 | C) then process partitions which haven't had a maintenance operation for 30 days in order of 161 | "compressed rowgroup count under 500k rows"/"rowgroup count" DESC 162 | D) then process partitions which haven't had a maintenance operation for 30 days in order of size DESC 163 | E) then process partitions with deleted + closed + open >= 1000 in order of percentage fragmentation DESC 164 | F) then process partitions in order of "compressed rowgroup count under 500k rows"/"rowgroup count" DESC 165 | G) ignore any other partitions 166 | 167 | CUSTOM_PRESET - uses an end user defined SQL expression. You must set a value for the 168 | @SQL_expression_for_partition_priority_calculation_CUSTOM_PRESET variable in this procedure to use this option. 169 | 170 | CUSTOM_USE_PARAMETER_EXPRESSION - uses the value supplied in the @SQL_expression_for_partition_priority_calculation parameter to do prioritization. 171 | 172 | 173 | @SQL_expression_for_partition_priority_calculation NVARCHAR(4000): 174 | 175 | A SQL expression used to set the priority order of index maintenance operations. Priority is set at the partition level and most 176 | columns in the CCI_Reorg_Rebuild_Partitions_To_Process table can be used to calculate the priority. This expression must evaluate to a value 177 | that can be cast to a NUMERIC(38, 0) for all partitions. Anything with a priority calculated as zero will not be processed. 178 | This parameter should not be set unless @partition_priority_algorithm_name = N'CUSTOM_USE_PARAMETER_EXPRESSION'. 179 | Note that using a column prefixed with cci_ requires a query against sys.dm_db_column_store_row_group_physical_stats which can be prohibitively expensive on some systems. 180 | 181 | Examples to show acceptable syntax: 182 | 183 | -- skip partitions with no rows, otherwise prioritize partitions that were stopped last time that weren't able to run for the full window, otherwise prioritize by least recent to be processed 184 | CASE WHEN cci_part_row_count = 0 THEN 0 185 | WHEN alter_last_attempt_status_flag = 3 THEN 987654321987654321987654321 186 | WHEN alter_last_complete_time IS NULL THEN 987654321987654321 187 | ELSE DATEDIFF(HOUR, alter_last_complete_time, SYSUTCDATETIME()) 188 | END 189 | 190 | -- skip any partition not in the four right most partitions, otherwise order by number of not compressed rows in a partition 191 | CASE WHEN sql_part_distance_from_rightmost_partition >= 4 THEN 0 192 | ELSE cci_part_open_row_count + cci_part_deleted_row_count + cci_part_closed_row_count + cci_part_tombstone_row_count 193 | END 194 | 195 | 196 | Here is the full list of columns available in the CCI_Reorg_Rebuild_Partitions_To_Process table along with some explanations: 197 | 198 | Database_Name SYSNAME NOT NULL, 199 | [Schema_Name] SYSNAME NOT NULL, 200 | Table_Name SYSNAME NOT NULL, 201 | Index_Name SYSNAME NOT NULL, 202 | Partition_Number INT NOT NULL, -- set to -1 for unpartitioned tables 203 | Database_Id INT NOT NULL, 204 | Object_Id INT NOT NULL, 205 | maxdop_limit SMALLINT NULL, -- does not account for size of partition, only looks at database and system settings 206 | partition_is_archive_compressed BIT NULL, 207 | alter_last_attempt_time_utc DATETIME2 NULL, -- the time a partition was last processed by this maintenance solution with any outcome 208 | alter_last_attempt_status_flag TINYINT NULL, -- 1 for completion, 2 for stopped after running for entire maintenance window, 3 for stopped after running for part of maintenance window, 4 for error 209 | alter_last_attempt_was_rebuild BIT NULL, -- 1 if the most recent maintenance action for a partition was a REBUILD 210 | alter_last_complete_time DATETIME2 NULL, -- most recent time a maintenance operation for a partition was successful 211 | alter_last_partial_timeout_time_utc DATETIME2 NULL, -- most recent time a maintenance operation for a partition timed out after running for part of the maintenance window 212 | alter_last_full_timeout_time_utc DATETIME2 NULL, -- most recent time a maintenance operation for a partition timed out after running for the full window 213 | alter_last_error_time DATETIME2 NULL, -- most recent time a maintenance operation for a partition had an error 214 | sql_part_approx_row_count BIGINT DEFAULT 0, -- number of rows from sys.dm_db_partition_stats 215 | sql_part_approx_bytes BIGINT DEFAULT 0, -- number of used bytes from sys.dm_db_partition_stats 216 | sql_table_approx_row_count BIGINT DEFAULT 0, 217 | sql_table_approx_bytes BIGINT DEFAULT 0, 218 | sql_part_distance_from_rightmost_partition INT DEFAULT 0, -- set to 1 for the right most partition, 2 for the second right most partition, etc 219 | cci_part_row_count BIGINT DEFAULT 0, -- number of rows from sys.dm_db_column_store_row_group_physical_stats 220 | cci_part_open_row_count BIGINT DEFAULT 0, 221 | cci_part_compressed_row_count BIGINT DEFAULT 0, 222 | cci_part_deleted_row_count BIGINT DEFAULT 0, 223 | cci_part_closed_row_count BIGINT DEFAULT 0, 224 | cci_part_tombstone_row_count BIGINT DEFAULT 0, 225 | cci_part_dict_pressure_row_count BIGINT DEFAULT 0, 226 | cci_part_memory_pressure_row_count BIGINT DEFAULT 0, 227 | cci_part_rowgroup_count BIGINT DEFAULT 0, -- number of rowgroups from sys.dm_db_column_store_row_group_physical_stats 228 | cci_part_open_rowgroup_count BIGINT DEFAULT 0, 229 | cci_part_compressed_rowgroup_count BIGINT DEFAULT 0, 230 | cci_part_closed_rowgroup_count BIGINT DEFAULT 0, 231 | cci_part_tombstone_rowgroup_count BIGINT DEFAULT 0, 232 | cci_part_compressed_rowgroup_count_under_17k_rows BIGINT DEFAULT 0, 233 | cci_part_compressed_rowgroup_count_under_132k_rows BIGINT DEFAULT 0, 234 | cci_part_compressed_rowgroup_count_under_263k_rows BIGINT DEFAULT 0, 235 | cci_part_compressed_rowgroup_count_under_525k_rows BIGINT DEFAULT 0, 236 | cci_part_dict_pressure_rowgroup_count BIGINT DEFAULT 0, 237 | cci_part_memory_pressure_rowgroup_count BIGINT DEFAULT 0, 238 | cci_part_approx_deleted_rows_bytes BIGINT DEFAULT 0, -- a guess at bytes used by deleted rows using sys.dm_db_column_store_row_group_physical_stats 239 | cci_part_approx_compressed_bytes BIGINT DEFAULT 0, 240 | cci_part_approx_uncompressed_bytes BIGINT DEFAULT 0, 241 | cci_part_total_bytes BIGINT DEFAULT 0, 242 | cci_table_total_bytes BIGINT DEFAULT 0, -- total bytes for the table using sys.dm_db_column_store_row_group_physical_stats 243 | cci_table_row_count BIGINT DEFAULT 0, -- total rows for the table using sys.dm_db_column_store_row_group_physical_stats 244 | cci_table_open_row_count BIGINT DEFAULT 0, 245 | cci_table_compressed_row_count BIGINT DEFAULT 0, 246 | cci_table_deleted_row_count BIGINT DEFAULT 0, 247 | cci_table_closed_row_count BIGINT DEFAULT 0, 248 | cci_table_tombstone_row_count BIGINT DEFAULT 0, 249 | 250 | 251 | @rebuild_algorithm_name NVARCHAR(100): 252 | 253 | Choose the algorithm to determine if an index operation should be a REBUILD or a REORGANIZE. Choices are: 254 | 255 | DEFAULT - uses the default algorithm set in this procedure. This may change over time. Current logic: 256 | A) don't do rebuild if the last maintenance operation on the partition was a rebuild that was stopped after running for the full maintenance window 257 | B) do a rebuild if the partition has at least 8 million rows and the ratio of deleted rows to total rows exceeds 1.6 / "available maxdop" 258 | 259 | CUSTOM_PRESET - uses an end user defined SQL expression. You must set a value for the 260 | @SQL_expression_for_rebuild_calculation_CUSTOM_PRESET variable in this procedure to use this option. 261 | 262 | CUSTOM_USE_PARAMETER_EXPRESSION - uses the value supplied in the @SQL_expression_for_rebuild_calculation to do prioritization. 263 | 264 | NEVER - all index operations use REORGANIZE. 265 | 266 | ALWAYS - all index operations use REBUILD. 267 | 268 | 269 | @SQL_expression_for_rebuild_calculation NVARCHAR(4000): 270 | 271 | A SQL expression used to determine if a partition should undergo a REBUILD or a REORGANIZE. The value of this expression is cast to a BIT 272 | so anything > 0 will be considered to be a REBUILD. This parameter should not be set unless @rebuild_algorithm_name = N'CUSTOM_USE_PARAMETER_EXPRESSION'. 273 | Note that using a column prefixed with cci_ requires a query against sys.dm_db_column_store_row_group_physical_stats which can be prohibitively expensive on some systems. 274 | 275 | Example to show acceptable syntax: 276 | 277 | -- rebuild anything with at least 4 million deleted rows if available MAXDOP >= 4 and the partition is not archive compressed: 278 | CASE WHEN cci_part_deleted_row_count > 4000000 AND maxdop_limit >= 4 AND partition_is_archive_compressed = 0 THEN 1 ELSE 0 END 279 | 280 | Reference the @SQL_expression_for_partition_priority_calculation parameter to see a list of available columns to use for the calculation. 281 | 282 | 283 | @ignore_archive_compressed_partitions BIT: 284 | 285 | Exclude archive compressed partitions from the search for indexes that could benefit from maintenance. By default these are excluded. If set to 0 you can use the partition_is_archive_compressed column to prioritize archive compressed partitions differently from partitions with standard columnstore compression. 286 | 287 | 288 | @reorg_use_COMPRESS_ALL_ROWGROUPS_option BIT: 289 | 290 | Controls the COMPRESS_ALL_ROW_GROUP option for ALTER INDEX... REORGANIZE. With the default value of this parameter, REORGANIZE statements will run with COMPRESS_ALL_ROW_GROUP = ON. Change that by setting this parameter to 0. 291 | 292 | 293 | @reorg_execute_twice BIT: 294 | 295 | ALTER INDEX... REORGANIZE does not always result in a table or partition without any fragmentation. For example, TOMBSTONE rowgroups may be left behind after a REORGANIZE. Set this parameter to 1 to immediately run another REORGANIZE on the table or partition after the first has completed. rowgroups. This can be helpful for some workloads in that it will immediately remove the TOMBSTONE rowgroups. 296 | 297 | 298 | @rebuild_MAXDOP SMALLINT: 299 | 300 | Set this parameter to set the MAXDOP option for ALTER INDEX... REBUILD. By default the MAXDOP option won't be passed to the REBUILD statement. The actual DOP of the REBUILD can be impacted by many things, including MAXDOP settings at any level, cardinality estimates for the partition, and expected memory usage needed to compress the data. 301 | 302 | 303 | @rebuild_ONLINE_option BIT: 304 | 305 | Controls the ONLINE option for ALTER INDEX... REBUILD which was introduced by Microsoft with SQL Server 2019. With the default value of this parameter, REBUILD statements will run with ONLINE = OFF. Note that rebuilds even with ONLINE = OFF are "partially online". The data in the partition can be read by not modified. 306 | 307 | 308 | @start_stored_procedure_name_to_run SYSNAME: 309 | 310 | Specify the name of a stored procedure that exists on the current stored procedure database and in the stored procedure schema to run at the start of maintenance. This can be used to quiesce an application. If the stored procedure throws an error then maintenance will not run. 311 | 312 | 313 | @end_stored_procedure_name_to_run SYSNAME: 314 | 315 | Specify the name of a stored procedure that exists on the current stored procedure database and in the stored procedure schema to run at the end of maintenance during cleanup. 316 | 317 | 318 | @disable_CPU_rescheduling BIT: 319 | 320 | ALTER INDEX... REORGANIZE always runs with MAXDOP 1. It can be helpful for overall throughput to try to nudge long running, 321 | MAXDOP 1 processes onto their own schedulers. The maintenance solution checks the scheduler assigned to the child jobs 322 | and restarts the child job if another child job is already running on that scheduler. Child jobs will restart up to 25 times 323 | to try to get on their own schedulers. This behavior is disabled by setting this parameter to 1. 324 | 325 | 326 | @delimiter_override NVARCHAR(1): 327 | 328 | Set this parameter to change the default delimiter from a comma to something else for the @CCI_included_database_name_list, @CCI_excluded_schema_name_list, and @CCI_excluded_table_name_list parameters. 329 | 330 | 331 | @job_prefix_override NVARCHAR(20): 332 | 333 | This stored procedure creates agent jobs with a prefix of "CCI_Reorg_Rebuild" by default. Set this parameter if you need to append additional characters to that prefix for any reason. 334 | 335 | 336 | @prioritization_only BIT: 337 | 338 | Setting this parameter to 1 runs the maintenance solution in test mode. Prioritization of all partitions is set but no ALTER INDEX... statements are run. This mode can be useful for verifying that no errors are thrown and validating that the partition priority and rebuild algorithm calculations are working as expected. The following query can be useful for that type of analysis: 339 | 340 | SELECT * 341 | FROM CCI_Reorg_Rebuild_Partitions_To_Process 342 | ORDER BY String_Priority_Helper DESC 343 | 344 | */ 345 | 346 | 347 | 348 | -- IMPORTANT: set the @Disable_SQL_Expression_Parameters variable to 1 if you want to disable 349 | -- the @SQL_expression_for_partition_priority_calculation and @SQL_expression_for_rebuild_calculation parameters 350 | DECLARE @Disable_SQL_Expression_Parameters BIT = 0; 351 | 352 | -- IMPORTANT: set the variable below if you wish to use the CUSTOM_PRESET option for the @partition_priority_algorithm_name parameter 353 | DECLARE @SQL_expression_for_partition_priority_calculation_CUSTOM_PRESET NVARCHAR(4000) = NULL; 354 | 355 | -- IMPORTANT: set the variable below if you wish to use the CUSTOM_PRESET option for @rebuild_algorithm_name parameter 356 | DECLARE @SQL_expression_for_rebuild_calculation_CUSTOM_PRESET NVARCHAR(4000) = NULL; 357 | 358 | 359 | 360 | DECLARE @workload_identifier NVARCHAR(50) = N'CCI_Reorg_Rebuild', 361 | @child_stored_procedure_name SYSNAME = N'CCI_Reorg_Rebuild_Child_Job', 362 | @cleanup_stored_procedure_name SYSNAME = N'CCI_Reorg_Rebuild_Cleanup_Jobs', 363 | @code_database_name SYSNAME, 364 | @code_schema_name SYSNAME, 365 | @parm_definition NVARCHAR(4000), 366 | @dynamic_sql_max NVARCHAR(MAX) = CAST(N'' AS NVARCHAR(MAX)), 367 | @view_text NVARCHAR(MAX) = CAST(N'' AS NVARCHAR(MAX)), 368 | @view_name_with_schema NVARCHAR(400), 369 | @dynamic_sql_result_set_exists BIT = 0, 370 | @is_valid_initial BIT, 371 | @parent_start_time DATETIME2 = SYSUTCDATETIME(), 372 | @product_version INT, 373 | @database_count BIGINT, 374 | @actual_database_count BIGINT, 375 | @nice_error_message NVARCHAR(4000), 376 | @current_CCI_database_name SYSNAME, 377 | @current_CCI_database_id INT, 378 | @delimiter NVARCHAR(1) = ISNULL(@delimiter_override, N','), 379 | @query_part_level_info BIT = 0, 380 | @query_CCI_DMV_info BIT = 0, 381 | @query_history_table BIT = 0, 382 | @SQL_expression_for_partition_priority_calculation_DEFAULT NVARCHAR(4000), 383 | @SQL_expression_for_rebuild_calculation_DEFAULT NVARCHAR(4000), 384 | @SQL_expression_for_rebuild_calculation_NEVER NVARCHAR(4000), 385 | @SQL_expression_for_rebuild_calculation_ALWAYS NVARCHAR(4000), 386 | @used_SQL_expression_for_partition_priority_calculation NVARCHAR(4000), 387 | @used_SQL_expression_for_rebuild_calculation NVARCHAR(4000), 388 | @job_prefix NVARCHAR(20) = ISNULL(@job_prefix_override, N''), 389 | @MAXDOP_scheduler_limit SMALLINT, 390 | @MAXDOP_RG_limit_guess SMALLINT, 391 | @MAXDOP_standard_edition_limit SMALLINT, 392 | @MAXDOP_global_default SMALLINT, 393 | @MAXDOP_database_level_default SMALLINT, 394 | @MAXDOP_calculated_at_database_level SMALLINT; 395 | 396 | SET NOCOUNT ON; 397 | 398 | SET @code_database_name = DB_NAME(); -- all code objects are required to exist on the same database and schema 399 | SET @code_schema_name = OBJECT_SCHEMA_NAME(@@PROCID); 400 | SET @partition_priority_algorithm_name = ISNULL(@partition_priority_algorithm_name, N'DEFAULT'); 401 | SET @rebuild_algorithm_name = ISNULL(@rebuild_algorithm_name, N'DEFAULT'); 402 | SET @ignore_archive_compressed_partitions = ISNULL(@ignore_archive_compressed_partitions, 1); 403 | SET @reorg_use_COMPRESS_ALL_ROWGROUPS_option = ISNULL(@reorg_use_COMPRESS_ALL_ROWGROUPS_option, 1); 404 | SET @reorg_execute_twice = ISNULL(@reorg_execute_twice, 0); 405 | SET @rebuild_ONLINE_option = ISNULL(@rebuild_ONLINE_option, 0); 406 | SET @prioritization_only = ISNULL(@prioritization_only, 0); 407 | SET @disable_CPU_rescheduling = ISNULL(@disable_CPU_rescheduling, 0); 408 | 409 | -- set default algorithm for partition priority calculation 410 | SET @SQL_expression_for_partition_priority_calculation_DEFAULT = N'CASE WHEN cci_part_row_count < 1000 THEN 0 411 | WHEN cci_part_deleted_row_count + cci_part_closed_row_count + cci_part_open_row_count >= 100000 412 | THEN 10000000000000 + CAST(100.0 * (cci_part_deleted_row_count + cci_part_closed_row_count + cci_part_open_row_count) / cci_part_row_count AS INT) 413 | WHEN (alter_last_complete_time IS NULL OR DATEDIFF(DAY, alter_last_complete_time, SYSUTCDATETIME()) >= 30) 414 | AND (alter_last_full_timeout_time_utc IS NULL OR DATEDIFF(DAY, alter_last_full_timeout_time_utc, SYSUTCDATETIME()) >= 30) 415 | THEN 1000000000000 + 416 | CASE WHEN cci_part_compressed_rowgroup_count_under_525k_rows > 0 417 | THEN 100000000000 + CAST(100.0 * cci_part_compressed_rowgroup_count_under_525k_rows / cci_part_rowgroup_count AS INT) 418 | ELSE cci_part_total_bytes / 1000000 419 | END 420 | WHEN cci_part_deleted_row_count + cci_part_closed_row_count + cci_part_open_row_count >= 1000 421 | THEN 10000000000 + CAST(100.0 * (cci_part_deleted_row_count + cci_part_closed_row_count + cci_part_open_row_count) / cci_part_row_count AS INT) 422 | ELSE CAST(100.0 * cci_part_compressed_rowgroup_count_under_525k_rows / cci_part_rowgroup_count AS INT) 423 | END'; 424 | 425 | -- set default algorithm for rebuild calculation 426 | SET @SQL_expression_for_rebuild_calculation_DEFAULT = N' 427 | CASE 428 | WHEN alter_last_attempt_status_flag = 2 AND alter_last_attempt_was_rebuild = 1 429 | THEN 0 430 | WHEN sql_part_approx_row_count >= 8000000 AND (1.0 * cci_part_deleted_row_count / cci_part_row_count) > (1.6 / maxdop_limit) 431 | THEN 1 ELSE 0 432 | END'; 433 | SET @SQL_expression_for_rebuild_calculation_NEVER = N'0'; 434 | SET @SQL_expression_for_rebuild_calculation_ALWAYS = N'1'; 435 | 436 | 437 | -- set runtime expression values to be passed to the child procedures 438 | SET @used_SQL_expression_for_partition_priority_calculation = CASE @partition_priority_algorithm_name 439 | WHEN N'DEFAULT' THEN @SQL_expression_for_partition_priority_calculation_DEFAULT 440 | WHEN N'CUSTOM_PRESET' THEN @SQL_expression_for_partition_priority_calculation_CUSTOM_PRESET 441 | WHEN N'CUSTOM_USE_PARAMETER_EXPRESSION' THEN @SQL_expression_for_partition_priority_calculation 442 | ELSE NULL 443 | END; 444 | 445 | SET @used_SQL_expression_for_rebuild_calculation = CASE @rebuild_algorithm_name 446 | WHEN N'DEFAULT' THEN @SQL_expression_for_rebuild_calculation_DEFAULT 447 | WHEN N'CUSTOM_PRESET' THEN @SQL_expression_for_rebuild_calculation_CUSTOM_PRESET 448 | WHEN N'CUSTOM_USE_PARAMETER_EXPRESSION' THEN @SQL_expression_for_rebuild_calculation 449 | WHEN N'NEVER' THEN @SQL_expression_for_rebuild_calculation_NEVER 450 | WHEN N'ALWAYS' THEN @SQL_expression_for_rebuild_calculation_ALWAYS 451 | ELSE NULL 452 | END; 453 | 454 | 455 | -- use stored procedure name and database for tables if optional logging parameters aren't set 456 | SET @logging_database_name = ISNULL(@logging_database_name, DB_NAME()); 457 | SET @logging_schema_name = ISNULL(@logging_schema_name, OBJECT_SCHEMA_NAME(@@PROCID)); 458 | 459 | 460 | SET @is_valid_initial = 1; 461 | EXEC [dbo].AgentJobMultiThread_InitialValidation 462 | @workload_identifier = @workload_identifier, 463 | @logging_database_name = @logging_database_name, 464 | @logging_schema_name = @logging_schema_name, 465 | @parent_start_time = @parent_start_time, 466 | @child_stored_procedure_name = @child_stored_procedure_name, 467 | @cleanup_stored_procedure_name = @cleanup_stored_procedure_name, 468 | @max_minutes_to_run = @max_minutes_to_run, 469 | @total_jobs_to_create = @max_CCI_alter_job_count, 470 | @is_valid_OUT = @is_valid_initial OUTPUT, 471 | @error_message_OUT = @nice_error_message OUTPUT; 472 | 473 | IF @is_valid_initial = 0 474 | BEGIN 475 | THROW 50000, @nice_error_message, 1; 476 | RETURN; 477 | END; 478 | 479 | 480 | -- fail if on older version than 2017 RTM or 2016 SP2 481 | -- this is currently redundant but might matter if AgentJobMultiThread_InitialValidation is updated to work with SQL Server 2014 482 | SET @product_version = TRY_CAST(PARSENAME(CONVERT(NVARCHAR(20),SERVERPROPERTY('ProductVersion')), 4) AS INT); 483 | 484 | IF @product_version < 13 OR (@product_version = 13 AND TRY_CAST(PARSENAME(CONVERT(NVARCHAR(20),SERVERPROPERTY('ProductVersion')), 2) AS INT) < 5026) 485 | BEGIN 486 | THROW 50140, 'Not tested on versions older than SQL Server 2016 SP2 and SQL Server 2017 RTM. Comment this code out at your own risk.', 1; 487 | RETURN; 488 | END; 489 | 490 | 491 | -- ONLINE rebuild for CCI not supported until SQL Server 2019 492 | IF @rebuild_ONLINE_option = 1 AND @product_version < 15 493 | BEGIN 494 | THROW 50005, 'ONLINE rebuild for CCI not supported until SQL Server 2019. Change @rebuild_ONLINE_option to 0.', 1; 495 | RETURN; 496 | END; 497 | 498 | 499 | IF NOT EXISTS ( 500 | SELECT [compatibility_level] 501 | FROM sys.databases 502 | WHERE [name] = @code_database_name 503 | AND [compatibility_level] >= 130 504 | ) 505 | BEGIN 506 | SET @nice_error_message = N'Compatibility level of at least 130 is required for the ' + QUOTENAME(@code_database_name) + N' database.'; 507 | THROW 50145, @nice_error_message, 1; 508 | RETURN; 509 | END; 510 | 511 | 512 | -- all necessary tables were created in the logging database and schema 513 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'SELECT @dynamic_sql_result_set_exists_OUT = 1 514 | FROM ' + QUOTENAME(@logging_database_name) + N'.sys.tables t 515 | INNER JOIN ' + QUOTENAME(@logging_database_name) + N'.sys.schemas s ON t.[schema_id] = s.[schema_id] 516 | where t.name IN (N''CCI_Reorg_Rebuild_Summary'', N''CCI_Reorg_Rebuild_Index_History'') 517 | AND s.name = @logging_schema_name 518 | HAVING COUNT_BIG(*) = 2'; 519 | 520 | SET @dynamic_sql_result_set_exists = 0; 521 | EXEC sp_executesql @dynamic_sql_max, 522 | N'@logging_schema_name SYSNAME, @dynamic_sql_result_set_exists_OUT BIT OUTPUT', 523 | @logging_schema_name = @logging_schema_name, 524 | @dynamic_sql_result_set_exists_OUT = @dynamic_sql_result_set_exists OUTPUT; 525 | 526 | IF @dynamic_sql_result_set_exists = 0 527 | BEGIN 528 | THROW 50030, 'Cannot find required tables in logging database and schema. Check parameter values for @logging_database_name and @logging_schema_name or run the setup script again.', 1; 529 | RETURN; 530 | END; 531 | 532 | -- all necessary procedures exist in the current database and schema 533 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'SELECT @dynamic_sql_result_set_exists_OUT = 1 534 | FROM ' + QUOTENAME(@code_database_name) + N'.sys.objects o 535 | INNER JOIN ' + QUOTENAME(@code_database_name) + N'.sys.schemas s ON o.[schema_id] = s.[schema_id] 536 | where o.name IN (N''CCI_Reorg_Rebuild_Child_Job'', N''CCI_Reorg_Rebuild_Cleanup_Jobs'',N''AgentJobMultiThread_InitialValidation'') 537 | AND s.name = @code_schema_name 538 | AND o.type = ''P'' 539 | HAVING COUNT_BIG(*) = 3'; 540 | 541 | SET @dynamic_sql_result_set_exists = 0; 542 | EXEC sp_executesql @dynamic_sql_max, 543 | N'@code_schema_name SYSNAME, @dynamic_sql_result_set_exists_OUT BIT OUTPUT', 544 | @code_schema_name = @code_schema_name, 545 | @dynamic_sql_result_set_exists_OUT = @dynamic_sql_result_set_exists OUTPUT; 546 | 547 | IF @dynamic_sql_result_set_exists = 0 548 | BEGIN 549 | THROW 50035, 'Cannot find required stored procedures in logging database and schema. Check parameter values or run the setup script again.', 1; 550 | RETURN; 551 | END; 552 | 553 | -- early validation of algorithm parameters 554 | IF @Disable_SQL_Expression_Parameters = 1 AND @partition_priority_algorithm_name = N'CUSTOM_USE_PARAMETER_EXPRESSION' 555 | BEGIN 556 | THROW 50061, 'CUSTOM_USE_PARAMETER_EXPRESSION option disabled by admin.', 1; 557 | RETURN; 558 | END; 559 | 560 | IF @Disable_SQL_Expression_Parameters = 1 AND @rebuild_algorithm_name = N'CUSTOM_USE_PARAMETER_EXPRESSION' 561 | BEGIN 562 | THROW 50071, 'CUSTOM_USE_PARAMETER_EXPRESSION option disabled by admin.', 1; 563 | RETURN; 564 | END; 565 | 566 | 567 | -- this procedure cannot be called until the previous run has completed or should have completed 568 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'SELECT TOP (1) @dynamic_sql_result_set_exists_OUT = 1 569 | FROM 570 | ( 571 | SELECT TOP (1) Summary_Start_Time_UTC, Max_Minutes_To_Run, Summary_End_Time_UTC 572 | FROM ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Summary 573 | ORDER BY Summary_Start_Time_UTC DESC 574 | ) q 575 | WHERE q.Summary_End_Time_UTC IS NULL AND SYSUTCDATETIME() < DATEADD(MINUTE, 1 + Max_Minutes_To_Run, Summary_Start_Time_UTC)'; 576 | 577 | SET @dynamic_sql_result_set_exists = 0; 578 | EXEC sp_executesql @dynamic_sql_max, 579 | N'@dynamic_sql_result_set_exists_OUT BIT OUTPUT', 580 | @dynamic_sql_result_set_exists_OUT = @dynamic_sql_result_set_exists OUTPUT; 581 | 582 | IF @dynamic_sql_result_set_exists = 1 583 | BEGIN 584 | SET @nice_error_message = N'Cannot run CCIReorgAndRebuild if previous run has not completed. Wait for the cleanup procedure to complete.' 585 | + N' To clean up after a failed run, examine the CCI_Reorg_Rebuild_Summary table and consider running a query similar to: 586 | " WITH CTE AS (SELECT TOP (1) * FROM ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Summary ORDER BY Summary_Start_Time_UTC DESC) DELETE FROM CTE; "'; 587 | 588 | THROW 50120, @nice_error_message, 1; 589 | RETURN; 590 | END; 591 | 592 | 593 | -- changing table or column names after release can break compatibility so don't do that ever 594 | -- also can't create columns that contain "GO" 595 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'DROP TABLE IF EXISTS ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Partitions_To_Process'; 596 | 597 | EXEC sp_executesql @dynamic_sql_max; 598 | 599 | -- use a string for the computed column instead of binary because conversion rules to binary can change between releases. 600 | -- also non-negative NUMERIC to BINARY currently doesn't preserve order 601 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'CREATE TABLE ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Partitions_To_Process ( 602 | Database_Name SYSNAME NOT NULL, 603 | Schema_Name SYSNAME NOT NULL, 604 | Table_Name SYSNAME NOT NULL, 605 | Index_Name SYSNAME NOT NULL, 606 | Partition_Number INT NOT NULL, 607 | Database_Id INT NOT NULL, 608 | Object_Id INT NOT NULL, 609 | maxdop_limit SMALLINT NULL, 610 | partition_is_archive_compressed BIT NULL, 611 | alter_last_attempt_time_utc DATETIME2 NULL, 612 | alter_last_attempt_status_flag TINYINT NULL, 613 | alter_last_attempt_was_rebuild BIT NULL, 614 | alter_last_complete_time DATETIME2 NULL, 615 | alter_last_partial_timeout_time_utc DATETIME2 NULL, 616 | alter_last_full_timeout_time_utc DATETIME2 NULL, 617 | alter_last_error_time DATETIME2 NULL, 618 | sql_part_approx_row_count BIGINT DEFAULT 0, 619 | sql_part_approx_bytes BIGINT DEFAULT 0, 620 | sql_table_approx_row_count BIGINT DEFAULT 0, 621 | sql_table_approx_bytes BIGINT DEFAULT 0, 622 | sql_part_distance_from_rightmost_partition INT DEFAULT 0, 623 | cci_part_row_count BIGINT DEFAULT 0, 624 | cci_part_open_row_count BIGINT DEFAULT 0, 625 | cci_part_compressed_row_count BIGINT DEFAULT 0, 626 | cci_part_deleted_row_count BIGINT DEFAULT 0, 627 | cci_part_closed_row_count BIGINT DEFAULT 0, 628 | cci_part_tombstone_row_count BIGINT DEFAULT 0, 629 | cci_part_dict_pressure_row_count BIGINT DEFAULT 0, 630 | cci_part_memory_pressure_row_count BIGINT DEFAULT 0, 631 | cci_part_rowgroup_count BIGINT DEFAULT 0, 632 | cci_part_open_rowgroup_count BIGINT DEFAULT 0, 633 | cci_part_compressed_rowgroup_count BIGINT DEFAULT 0, 634 | cci_part_closed_rowgroup_count BIGINT DEFAULT 0, 635 | cci_part_tombstone_rowgroup_count BIGINT DEFAULT 0, 636 | cci_part_compressed_rowgroup_count_under_17k_rows BIGINT DEFAULT 0, 637 | cci_part_compressed_rowgroup_count_under_132k_rows BIGINT DEFAULT 0, 638 | cci_part_compressed_rowgroup_count_under_263k_rows BIGINT DEFAULT 0, 639 | cci_part_compressed_rowgroup_count_under_525k_rows BIGINT DEFAULT 0, 640 | cci_part_dict_pressure_rowgroup_count BIGINT DEFAULT 0, 641 | cci_part_memory_pressure_rowgroup_count BIGINT DEFAULT 0, 642 | cci_part_approx_deleted_rows_bytes BIGINT DEFAULT 0, 643 | cci_part_approx_compressed_bytes BIGINT DEFAULT 0, 644 | cci_part_approx_uncompressed_bytes BIGINT DEFAULT 0, 645 | cci_part_total_bytes BIGINT DEFAULT 0, 646 | cci_table_total_bytes BIGINT DEFAULT 0, 647 | cci_table_row_count BIGINT DEFAULT 0, 648 | cci_table_open_row_count BIGINT DEFAULT 0, 649 | cci_table_compressed_row_count BIGINT DEFAULT 0, 650 | cci_table_deleted_row_count BIGINT DEFAULT 0, 651 | cci_table_closed_row_count BIGINT DEFAULT 0, 652 | cci_table_tombstone_row_count BIGINT DEFAULT 0, 653 | Calculated_Do_REBUILD BIT NOT NULL DEFAULT 0, 654 | Calculated_Priority NUMERIC(38, 0) NOT NULL DEFAULT 0, 655 | In_Progress SMALLINT NOT NULL, 656 | Prioritization_Complete_Time_UTC DATETIME2 NULL, 657 | Job_Number_That_Calculated_Priority SMALLINT NULL, 658 | Job_Number_That_Attempted_Alter SMALLINT NULL, 659 | String_Priority_Helper AS RIGHT(REPLICATE(''0'', 38) + CAST(Calculated_Priority AS VARCHAR(38)), 38) + 660 | RIGHT(''0000000000'' + CAST(Database_Id AS VARCHAR(10)), 10) + RIGHT(''0000000000'' + CAST(Object_Id AS VARCHAR(10)), 10), 661 | CONSTRAINT [CHK_NO_NEGATIVE_PRIORITY_' + SUBSTRING(CAST(RAND() AS NVARCHAR(10)), 3, 9) + N'] CHECK (Calculated_Priority >= 0) 662 | ) WITH (DATA_COMPRESSION = ROW)' 663 | 664 | EXEC sp_executesql @dynamic_sql_max; 665 | 666 | 667 | -- validate and process @CCI_included_database_name_list parameter 668 | SELECT @database_count = COUNT_BIG([value]) 669 | FROM STRING_SPLIT(@CCI_included_database_name_list, @delimiter); 670 | 671 | DECLARE @CCI_Database_Names TABLE ([database_id] INT NOT NULL, [database_name] SYSNAME NOT NULL); 672 | 673 | INSERT INTO @CCI_Database_Names ([database_id], [database_name]) 674 | SELECT d.database_id, d.name 675 | FROM STRING_SPLIT(@CCI_included_database_name_list, @delimiter) ss 676 | INNER JOIN sys.databases d on ss.[value] = d.name; 677 | 678 | SELECT @actual_database_count = @@ROWCOUNT; 679 | 680 | IF @database_count <> @actual_database_count 681 | BEGIN 682 | THROW 50040, 'At least one database name cannot be found. Note that database names containing commas are likely to cause issues. Consider using the @delimiter_override parameter.', 1; 683 | RETURN; 684 | END; 685 | 686 | IF @actual_database_count = 0 687 | BEGIN 688 | THROW 50041, 'Must pass in at least one database name in the @CCI_included_database_name_list parameter.', 1; 689 | RETURN; 690 | END; 691 | 692 | 693 | -- check that user has necessary permissions and compat level on all databases 694 | DECLARE CCI_Databases_Permission_Check CURSOR FOR 695 | SELECT [database_name] 696 | FROM @CCI_Database_Names; 697 | 698 | OPEN CCI_Databases_Permission_Check; 699 | 700 | FETCH NEXT FROM CCI_Databases_Permission_Check INTO @current_CCI_database_name; 701 | 702 | WHILE @@FETCH_STATUS = 0 703 | BEGIN 704 | IF HAS_PERMS_BY_NAME(@current_CCI_database_name, N'DATABASE', N'CREATE TABLE') = 0 -- this was the closest fit I could find 705 | BEGIN 706 | SET @nice_error_message = N'Permission to alter indexes (db_ddl_admin for example) is needed on ' + QUOTENAME(@current_CCI_database_name) + N' database.'; 707 | THROW 50042, @nice_error_message, 1; 708 | RETURN; 709 | END; 710 | 711 | -- code throws error with compat 100 so catch that here - not sure why anyone would have CCIs in such a database though 712 | IF NOT EXISTS ( 713 | SELECT [compatibility_level] 714 | FROM sys.databases 715 | WHERE [name] = @current_CCI_database_name 716 | AND [compatibility_level] >= 110 717 | ) 718 | BEGIN 719 | SET @nice_error_message = N'Compat level cannot be level 100 in database ' + QUOTENAME(@current_CCI_database_name) + N'.'; 720 | THROW 50045, @nice_error_message, 1; 721 | RETURN; 722 | END; 723 | 724 | FETCH NEXT FROM CCI_Databases_Permission_Check INTO @current_CCI_database_name; 725 | END; 726 | 727 | CLOSE CCI_Databases_Permission_Check; 728 | 729 | DEALLOCATE CCI_Databases_Permission_Check; 730 | 731 | 732 | -- validate @CCI_Excluded_Schema_Names if only one CCI database was passed in 733 | IF @database_count = 1 AND @CCI_excluded_schema_name_list IS NOT NULL 734 | BEGIN 735 | SET @current_CCI_database_name = REPLACE(@CCI_included_database_name_list, @delimiter, N''); 736 | 737 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'SELECT TOP (1) @dynamic_sql_result_set_exists_OUT = 1 738 | FROM STRING_SPLIT(@CCI_excluded_schema_name_list, @delimiter) split 739 | WHERE NOT EXISTS ( 740 | SELECT 1 741 | FROM ' + QUOTENAME(@current_CCI_database_name) + N'.sys.schemas ss 742 | WHERE split.[value] = ss.[name] 743 | )'; 744 | 745 | SET @dynamic_sql_result_set_exists = 0; 746 | EXEC sp_executesql @dynamic_sql_max, 747 | N'@CCI_excluded_schema_name_list NVARCHAR(4000), @delimiter NVARCHAR(1), @dynamic_sql_result_set_exists_OUT BIT OUTPUT', 748 | @CCI_excluded_schema_name_list = @CCI_excluded_schema_name_list, 749 | @delimiter = @delimiter, 750 | @dynamic_sql_result_set_exists_OUT = @dynamic_sql_result_set_exists OUTPUT; 751 | 752 | IF @dynamic_sql_result_set_exists = 1 753 | BEGIN 754 | THROW 50043, 'Cannot find at least one schema in the @CCI_excluded_schema_name_list parameter.', 1; 755 | RETURN; 756 | END; 757 | END; 758 | 759 | 760 | -- validate @CCI_excluded_table_name_list if only one CCI database was passed in 761 | IF @database_count = 1 AND @CCI_excluded_table_name_list IS NOT NULL 762 | BEGIN 763 | SET @current_CCI_database_name = REPLACE(@CCI_included_database_name_list, @delimiter, N''); 764 | 765 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'SELECT TOP (1) @dynamic_sql_result_set_exists_OUT = 1 766 | FROM STRING_SPLIT(@CCI_excluded_table_name_list, @delimiter) split 767 | WHERE NOT EXISTS ( 768 | SELECT 1 769 | FROM ' + QUOTENAME(@current_CCI_database_name) + N'.sys.tables t 770 | WHERE split.[value] = t.[name] 771 | )'; 772 | 773 | SET @dynamic_sql_result_set_exists = 0; 774 | EXEC sp_executesql @dynamic_sql_max, 775 | N'@CCI_excluded_table_name_list NVARCHAR(4000), @delimiter NVARCHAR(1), @dynamic_sql_result_set_exists_OUT BIT OUTPUT', 776 | @CCI_excluded_table_name_list = @CCI_excluded_table_name_list, 777 | @delimiter = @delimiter, 778 | @dynamic_sql_result_set_exists_OUT = @dynamic_sql_result_set_exists OUTPUT; 779 | 780 | IF @dynamic_sql_result_set_exists = 1 781 | BEGIN 782 | THROW 50046, 'Cannot find at least one table in the @CCI_excluded_table_name_list parameter.', 1; 783 | RETURN; 784 | END; 785 | END; 786 | 787 | 788 | -- process @CCI_Excluded_Schema_Names 789 | CREATE TABLE #CCI_Excluded_Schema_Names ([schema_name] SYSNAME NOT NULL); 790 | 791 | BEGIN TRY 792 | INSERT INTO #CCI_Excluded_Schema_Names ([schema_name]) 793 | SELECT [value] 794 | FROM STRING_SPLIT(@CCI_excluded_schema_name_list, @delimiter); 795 | END TRY 796 | BEGIN CATCH 797 | -- most likely error 8152 or 2628 but no reason to catch that 798 | SET @nice_error_message = N'Error when processing @CCI_excluded_schema_name_list.' 799 | + N' Error number: ' + CAST(ERROR_NUMBER() AS NVARCHAR(10)) 800 | + N' Error message: ' + LEFT(ERROR_MESSAGE(), 3600); 801 | 802 | THROW 50044, @nice_error_message, 1; 803 | END CATCH; 804 | 805 | -- process @CCI_excluded_table_name_list 806 | CREATE TABLE #CCI_Excluded_Table_Names ([table_name] SYSNAME NOT NULL); 807 | 808 | BEGIN TRY 809 | INSERT INTO #CCI_Excluded_Table_Names ([table_name]) 810 | SELECT [value] 811 | FROM STRING_SPLIT(@CCI_excluded_table_name_list, @delimiter); 812 | END TRY 813 | BEGIN CATCH 814 | -- most likely error 8152 or 2628 but no reason to catch that 815 | SET @nice_error_message = N'Error when processing @CCI_excluded_table_name_list.' 816 | + N' Error number: ' + CAST(ERROR_NUMBER() AS NVARCHAR(10)) 817 | + N' Error message: ' + LEFT(ERROR_MESSAGE(), 3600); 818 | 819 | THROW 50047, @nice_error_message, 1; 820 | END CATCH; 821 | 822 | 823 | -- validate numeric parameters 824 | IF @rebuild_MAXDOP <= 0 OR @max_CCI_alter_job_count IS NULL OR @max_CCI_alter_job_count <= 0 825 | BEGIN 826 | THROW 50050, 'Obvious error with @rebuild_MAXDOP and/or @max_CCI_alter_job_count parameter.', 1; 827 | RETURN; 828 | END; 829 | 830 | 831 | -- validate priority parameters 832 | IF @partition_priority_algorithm_name NOT IN (N'DEFAULT', N'CUSTOM_PRESET', N'CUSTOM_USE_PARAMETER_EXPRESSION') 833 | BEGIN 834 | THROW 50060, 'Unimplemented value for @partition_priority_algorithm_name parameter. Check the documentation.', 1; 835 | RETURN; 836 | END; 837 | 838 | IF @partition_priority_algorithm_name = N'CUSTOM_PRESET' AND @SQL_expression_for_partition_priority_calculation_CUSTOM_PRESET IS NULL 839 | BEGIN 840 | THROW 50062, 'An admin must set the @SQL_expression_for_partition_priority_calculation_CUSTOM_PRESET local variable to enable the CUSTOM_PRESET option.', 1; 841 | RETURN; 842 | END; 843 | 844 | IF @partition_priority_algorithm_name = N'CUSTOM_USE_PARAMETER_EXPRESSION' AND @SQL_expression_for_partition_priority_calculation IS NULL 845 | BEGIN 846 | THROW 50064, 'Value must be set for @SQL_expression_for_partition_priority_calculation when CUSTOM_USE_PARAMETER_EXPRESSION option is selected.', 1; 847 | RETURN; 848 | END; 849 | 850 | IF @partition_priority_algorithm_name <> N'CUSTOM_USE_PARAMETER_EXPRESSION' AND @SQL_expression_for_partition_priority_calculation IS NOT NULL 851 | BEGIN 852 | THROW 50066, 'Setting a value for @SQL_expression_for_partition_priority_calculation is not supported because the CUSTOM_USE_PARAMETER_EXPRESSION option is not selected.', 1; 853 | RETURN; 854 | END; 855 | 856 | IF @rebuild_algorithm_name NOT IN (N'DEFAULT', N'CUSTOM_PRESET', N'CUSTOM_USE_PARAMETER_EXPRESSION', N'NEVER', N'ALWAYS') 857 | BEGIN 858 | THROW 50070, 'Unimplemented value for @rebuild_algorithm_name parameter. Check the documentation.', 1; 859 | RETURN; 860 | END; 861 | 862 | IF @rebuild_algorithm_name = N'CUSTOM_PRESET' AND @SQL_expression_for_rebuild_calculation_CUSTOM_PRESET IS NULL 863 | BEGIN 864 | THROW 50072, 'An admin must set the @SQL_expression_for_rebuild_calculation_CUSTOM_PRESET local variable to enable the CUSTOM_PRESET option.', 1; 865 | RETURN; 866 | END; 867 | 868 | IF @rebuild_algorithm_name = N'CUSTOM_USE_PARAMETER_EXPRESSION' AND @SQL_expression_for_rebuild_calculation IS NULL 869 | BEGIN 870 | THROW 50074, 'Setting a value for @SQL_expression_for_rebuild_calculation is not supported because the CUSTOM_USE_PARAMETER_EXPRESSION option is not selected.', 1; 871 | RETURN; 872 | END; 873 | 874 | IF @rebuild_algorithm_name <> N'CUSTOM_USE_PARAMETER_EXPRESSION' AND @SQL_expression_for_rebuild_calculation IS NOT NULL 875 | BEGIN 876 | THROW 50076, 'Value set for @SQL_expression_for_rebuild_calculation will be ignored because CUSTOM_USE_PARAMETER_EXPRESSION option is not selected.', 1; 877 | RETURN; 878 | END; 879 | 880 | 881 | -- check that @SQL_expression_for_partition_priority_calculation and @used_SQL_expression_for_rebuild_calculation compile 882 | CREATE TABLE #expression_dependent_columns (column_name SYSNAME NOT NULL); 883 | 884 | IF @used_SQL_expression_for_partition_priority_calculation IS NOT NULL OR @used_SQL_expression_for_rebuild_calculation IS NOT NULL 885 | BEGIN 886 | -- a weak defense 887 | IF CHARINDEX(N'GO', @SQL_expression_for_partition_priority_calculation) > 0 OR CHARINDEX(N'GO', @SQL_expression_for_rebuild_calculation) > 0 888 | BEGIN 889 | THROW 50010, N'"GO" cannot be used in @SQL_expression_for_partition_priority_calculation or @SQL_expression_for_rebuild_calculation.', 1; 890 | RETURN; 891 | END; 892 | 893 | SET @view_name_with_schema = QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Get_Dependencies'; 894 | 895 | SET @view_text = CAST(N'' AS NVARCHAR(MAX)) + N'CREATE OR ALTER VIEW ' + @view_name_with_schema + N' AS 896 | SELECT CAST(' + ISNULL(@used_SQL_expression_for_partition_priority_calculation, N'0') + N' AS NUMERIC(38, 0)) COL1 897 | , CAST(' + ISNULL(@used_SQL_expression_for_rebuild_calculation, N'0') + N' AS BIT) COL2 898 | FROM ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Partitions_To_Process'; 899 | 900 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'USE ' + QUOTENAME(@logging_database_name) + N'; EXEC sp_executesql @view_text'; 901 | 902 | -- create the view 903 | BEGIN TRY 904 | EXEC sp_executesql @dynamic_sql_max, 905 | N'@view_text NVARCHAR(MAX)', 906 | @view_text = @view_text; 907 | END TRY 908 | BEGIN CATCH 909 | SET @nice_error_message = N'Error when validating @SQL_expression_for_partition_priority_calculation and @SQL_expression_for_rebuild_calculation.' 910 | + N' Error number: ' + CAST(ERROR_NUMBER() AS NVARCHAR(10)) 911 | + N' Error message: ' + LEFT(ERROR_MESSAGE(), 3600); 912 | 913 | THROW 50082, @nice_error_message, 1; 914 | RETURN; 915 | END CATCH; 916 | 917 | -- check for referenced tables other than CCI_Reorg_Rebuild_Partitions_To_Process 918 | SET @dynamic_sql_max = N'SELECT TOP (1) @dynamic_sql_result_set_exists_OUT = 1 919 | FROM ' + QUOTENAME(@logging_database_name) + N'.sys.dm_sql_referenced_entities (@view_name_with_schema, ''OBJECT'') 920 | WHERE referenced_entity_name <> N''CCI_Reorg_Rebuild_Partitions_To_Process'''; 921 | 922 | SET @dynamic_sql_result_set_exists = 0; 923 | EXEC sp_executesql @dynamic_sql_max, 924 | N'@view_name_with_schema NVARCHAR(400), @dynamic_sql_result_set_exists_OUT BIT OUTPUT', 925 | @view_name_with_schema = @view_name_with_schema, 926 | @dynamic_sql_result_set_exists_OUT = @dynamic_sql_result_set_exists OUTPUT; 927 | 928 | IF @dynamic_sql_result_set_exists = 1 929 | BEGIN 930 | THROW 50084, 'Cannot reference tables other than CCI_Reorg_Rebuild_Partitions_To_Process in @SQL_expression_for_partition_priority_calculation and @SQL_expression_for_rebuild_calculation.', 1; 931 | RETURN; 932 | END; 933 | 934 | -- check for compile errors. unfortunately can't catch some types of runtime errors like dividing by 0 935 | SET @dynamic_sql_max = N'SELECT @dynamic_sql_result_set_exists_OUT = CAST(COUNT_BIG(COL1) + COUNT_BIG(COL2) AS BIT) 936 | FROM ' + QUOTENAME(@logging_database_name) + N'.' + @view_name_with_schema; 937 | 938 | BEGIN TRY 939 | EXEC sp_executesql @dynamic_sql_max, 940 | N'@dynamic_sql_result_set_exists_OUT BIT OUTPUT', 941 | @dynamic_sql_result_set_exists_OUT = @dynamic_sql_result_set_exists OUTPUT; 942 | END TRY 943 | BEGIN CATCH 944 | SET @nice_error_message = N'Error when validating @SQL_expression_for_partition_priority_calculation and @SQL_expression_for_rebuild_calculation. ' 945 | + N'@SQL_expression_for_partition_priority_calculation must cast to a NUMERIC(38,0) and @SQL_expression_for_rebuild_calculation must cast to a BIT.' 946 | + N' Error number: ' + CAST(ERROR_NUMBER() AS NVARCHAR(10)) 947 | + N' Error message: ' + LEFT(ERROR_MESSAGE(), 3600); 948 | 949 | THROW 50086, @nice_error_message, 1; 950 | RETURN; 951 | END CATCH; 952 | 953 | -- get column list 954 | SET @dynamic_sql_max = N'INSERT INTO #expression_dependent_columns (column_name) 955 | SELECT DISTINCT referenced_minor_name 956 | FROM ' + QUOTENAME(@logging_database_name) + N'.sys.dm_sql_referenced_entities (@view_name_with_schema, ''OBJECT'') 957 | WHERE referenced_entity_name = N''CCI_Reorg_Rebuild_Partitions_To_Process'' 958 | AND referenced_minor_name IS NOT NULL'; 959 | 960 | EXEC sp_executesql @dynamic_sql_max, 961 | N'@view_name_with_schema NVARCHAR(400)', 962 | @view_name_with_schema = @view_name_with_schema; 963 | 964 | 965 | -- check for banned columns (lower case columns are always allowed) 966 | IF EXISTS (SELECT 1 967 | FROM #expression_dependent_columns 968 | WHERE column_name IN (N'Calculated_Do_REBUILD', N'Calculated_Priority', N'In_Progress', N'Binary_Priority_Helper', N'Prioritization_Complete_Time_UTC') 969 | ) 970 | BEGIN 971 | THROW 50088, N'@SQL_expression_for_partition_priority_calculation and @SQL_expression_for_rebuild_calculation cannot reference Calculated_Do_REBUILD, Calculated_Priority, In_Progress, Binary_Priority_Helper, or Prioritization_Complete_Time_UTC columns.', 1; 972 | RETURN; 973 | END; 974 | 975 | -- determine which DMVs and calculations need to happen later based on used columns in the expressions 976 | SELECT 977 | @query_part_level_info = MAX(CASE WHEN column_name LIKE N'sql[_]%' THEN 1 ELSE 0 END) 978 | , @query_CCI_DMV_info = MAX(CASE WHEN column_name LIKE N'cci[_]%' THEN 1 ELSE 0 END) 979 | , @query_history_table = MAX(CASE WHEN column_name LIKE N'alter[_]last[_]%' THEN 1 ELSE 0 END) 980 | FROM #expression_dependent_columns; 981 | 982 | -- drop the view 983 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'USE ' + QUOTENAME(@logging_database_name) + N'; DROP VIEW IF EXISTS ' + @view_name_with_schema; 984 | 985 | EXEC sp_executesql @dynamic_sql_max; 986 | END; 987 | 988 | 989 | -- validate @start_stored_procedure_name_to_run 990 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'SELECT @dynamic_sql_result_set_exists_OUT = 1 991 | FROM ' + QUOTENAME(@code_database_name) + N'.sys.objects o 992 | INNER JOIN ' + QUOTENAME(@code_database_name) + N'.sys.schemas s ON o.[schema_id] = s.[schema_id] 993 | where o.name = @stored_procedure_name 994 | AND s.name = @code_schema_name 995 | AND [type] = ''P'''; 996 | 997 | IF @start_stored_procedure_name_to_run IS NOT NULL 998 | BEGIN 999 | SET @dynamic_sql_result_set_exists = 1; 1000 | EXEC sp_executesql @dynamic_sql_max, 1001 | N'@stored_procedure_name SYSNAME, @code_schema_name SYSNAME, @dynamic_sql_result_set_exists_OUT BIT OUTPUT', 1002 | @stored_procedure_name = @start_stored_procedure_name_to_run, 1003 | @code_schema_name = @code_schema_name, 1004 | @dynamic_sql_result_set_exists_OUT = @dynamic_sql_result_set_exists OUTPUT; 1005 | 1006 | IF @dynamic_sql_result_set_exists = 0 1007 | BEGIN 1008 | THROW 50090, 'Cannot find @start_stored_procedure_name_to_run stored procedure. Be sure the stored procedure exists in the logging database and logging schema.', 1; 1009 | RETURN; 1010 | END; 1011 | END; 1012 | 1013 | 1014 | -- validate @end_stored_procedure_name_to_run 1015 | IF @end_stored_procedure_name_to_run IS NOT NULL 1016 | BEGIN 1017 | SET @dynamic_sql_result_set_exists = 1; 1018 | EXEC sp_executesql @dynamic_sql_max, 1019 | N'@stored_procedure_name SYSNAME, @code_schema_name SYSNAME, @dynamic_sql_result_set_exists_OUT BIT OUTPUT', 1020 | @stored_procedure_name = @end_stored_procedure_name_to_run, 1021 | @code_schema_name = @code_schema_name, 1022 | @dynamic_sql_result_set_exists_OUT = @dynamic_sql_result_set_exists OUTPUT; 1023 | 1024 | IF @dynamic_sql_result_set_exists = 0 1025 | BEGIN 1026 | THROW 50100, 'Cannot find @end_stored_procedure_name_to_run stored procedure. Be sure the stored procedure exists in the logging database and logging schema.', 1; 1027 | RETURN; 1028 | END; 1029 | END; 1030 | 1031 | 1032 | -- passed all error checks! 1033 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'INSERT INTO ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Summary 1034 | ( 1035 | Summary_Start_Time_UTC 1036 | , CCI_Included_Database_Name_List 1037 | , CCI_Excluded_Schema_Name_List 1038 | , CCI_Excluded_Table_Name_List 1039 | , Max_CCI_Alter_Job_Count 1040 | , Max_Minutes_To_Run 1041 | , Partition_Priority_Algorithm_Name 1042 | , Used_SQL_Expression_For_Partition_Priority_Calculation 1043 | , Rebuild_Algorithm_Name 1044 | , Used_SQL_Expression_For_Rebuild_Calculation 1045 | , Ignore_Archive_Compressed_Partitions 1046 | , Reorg_Use_COMPRESS_ALL_ROWGROUPS_Option 1047 | , Reorg_Execute_Twice 1048 | , Rebuild_MAXDOP 1049 | , Rebuild_ONLINE_Option 1050 | , Start_Stored_Procedure_Name_To_Run 1051 | , End_Stored_Procedure_Name_To_Run 1052 | , Disable_CPU_Rescheduling 1053 | , Delimiter_Override 1054 | , Used_Job_Prefix 1055 | , Prioritization_Only 1056 | , query_CCI_DMV_info 1057 | ) 1058 | VALUES 1059 | ( 1060 | @start_time 1061 | , @CCI_included_database_name_list 1062 | , @CCI_excluded_schema_name_list 1063 | , @CCI_excluded_table_name_list 1064 | , @max_CCI_alter_job_count 1065 | , @max_minutes_to_run 1066 | , @partition_priority_algorithm_name 1067 | , @used_SQL_expression_for_partition_priority_calculation 1068 | , @rebuild_algorithm_name 1069 | , @used_SQL_expression_for_rebuild_calculation 1070 | , @ignore_archive_compressed_partitions 1071 | , @reorg_use_COMPRESS_ALL_ROWGROUPS_option 1072 | , @reorg_execute_twice 1073 | , @rebuild_MAXDOP 1074 | , @rebuild_ONLINE_option 1075 | , @start_stored_procedure_name_to_run 1076 | , @end_stored_procedure_name_to_run 1077 | , @disable_CPU_rescheduling 1078 | , @delimiter_override 1079 | , @job_prefix 1080 | , @prioritization_only 1081 | , @query_CCI_DMV_info 1082 | )'; 1083 | 1084 | SET @parm_definition = N'@start_time DATETIME2, @CCI_included_database_name_list NVARCHAR(4000), @CCI_excluded_schema_name_list NVARCHAR(4000), @CCI_excluded_table_name_list NVARCHAR(4000)' 1085 | + N',@max_CCI_alter_job_count SMALLINT, @max_minutes_to_run SMALLINT, @partition_priority_algorithm_name NVARCHAR(100), @used_SQL_expression_for_partition_priority_calculation NVARCHAR(4000)' 1086 | + N',@rebuild_algorithm_name NVARCHAR(100), @used_SQL_expression_for_rebuild_calculation NVARCHAR(4000), @ignore_archive_compressed_partitions BIT' 1087 | + N',@reorg_use_COMPRESS_ALL_ROWGROUPS_option BIT, @reorg_execute_twice BIT, @rebuild_MAXDOP INT, @rebuild_ONLINE_option BIT,@start_stored_procedure_name_to_run SYSNAME' 1088 | + N',@end_stored_procedure_name_to_run SYSNAME, @disable_CPU_rescheduling BIT, @delimiter_override NVARCHAR(1), @job_prefix NVARCHAR(20), @prioritization_only BIT, @query_CCI_DMV_info BIT'; 1089 | 1090 | EXEC sp_executesql @dynamic_sql_max, 1091 | @parm_definition, 1092 | @start_time = @parent_start_time, 1093 | @CCI_included_database_name_list = @CCI_included_database_name_list, 1094 | @CCI_excluded_schema_name_list = @CCI_excluded_schema_name_list, 1095 | @CCI_excluded_table_name_list = @CCI_excluded_table_name_list, 1096 | @max_CCI_alter_job_count = @max_CCI_alter_job_count, 1097 | @max_minutes_to_run = @max_minutes_to_run, 1098 | @partition_priority_algorithm_name = @partition_priority_algorithm_name, 1099 | @used_SQL_expression_for_partition_priority_calculation = @used_SQL_expression_for_partition_priority_calculation, 1100 | @rebuild_algorithm_name = @rebuild_algorithm_name, 1101 | @used_SQL_expression_for_rebuild_calculation = @used_SQL_expression_for_rebuild_calculation, 1102 | @ignore_archive_compressed_partitions = @ignore_archive_compressed_partitions, 1103 | @reorg_use_COMPRESS_ALL_ROWGROUPS_option = @reorg_use_COMPRESS_ALL_ROWGROUPS_option, 1104 | @reorg_execute_twice = @reorg_execute_twice, 1105 | @rebuild_MAXDOP = @rebuild_MAXDOP, 1106 | @rebuild_ONLINE_option = @rebuild_ONLINE_option, 1107 | @start_stored_procedure_name_to_run = @start_stored_procedure_name_to_run, 1108 | @end_stored_procedure_name_to_run = @end_stored_procedure_name_to_run, 1109 | @disable_CPU_rescheduling = @disable_CPU_rescheduling, 1110 | @delimiter_override = @delimiter_override, 1111 | @job_prefix = @job_prefix, 1112 | @prioritization_only = @prioritization_only, 1113 | @query_CCI_DMV_info = @query_CCI_DMV_info; 1114 | 1115 | -- run custom start stored procedure if set 1116 | IF @start_stored_procedure_name_to_run IS NOT NULL 1117 | BEGIN 1118 | BEGIN TRY 1119 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + QUOTENAME(@code_schema_name) + N'.' + QUOTENAME(@start_stored_procedure_name_to_run); 1120 | EXEC sp_executesql @dynamic_sql_max; 1121 | END TRY 1122 | BEGIN CATCH 1123 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'UPDATE ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Summary 1124 | SET 1125 | Custom_Start_Procedure_Name_Error_Text = ERROR_MESSAGE() 1126 | , Summary_End_Time_UTC = SYSUTCDATETIME() 1127 | WHERE Summary_Start_Time_UTC = @start_time'; 1128 | 1129 | EXEC sp_executesql @dynamic_sql_max, 1130 | N'@start_time DATETIME2', 1131 | @start_time = @parent_start_time; 1132 | 1133 | SET @nice_error_message = N'Error with custom start procedure.' 1134 | + N' Error number: ' + CAST(ERROR_NUMBER() AS NVARCHAR(10)) 1135 | + N' Error message: ' + LEFT(ERROR_MESSAGE(), 3600); 1136 | 1137 | THROW 50110, @nice_error_message, 1; 1138 | 1139 | RETURN; 1140 | END CATCH; 1141 | END; 1142 | 1143 | 1144 | -- quit if the custom procedure uses up all available time 1145 | IF DATEADD(MINUTE, @max_minutes_to_run, @parent_start_time) <= SYSUTCDATETIME() 1146 | BEGIN 1147 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'UPDATE ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Summary 1148 | SET Summary_End_Time_UTC = SYSUTCDATETIME() 1149 | , Alter_Statements_Completed = 0 1150 | , Alter_Statements_Halted = 0 1151 | , Alter_Statements_Not_Started = 0 1152 | , Approximate_Error_Count = 0 1153 | , Alter_Total_CPU_MS = 0 1154 | WHERE Summary_Start_Time_UTC = @start_time'; 1155 | 1156 | EXEC sp_executesql @dynamic_sql_max, 1157 | N'@start_time DATETIME2', 1158 | @start_time = @parent_start_time; 1159 | 1160 | RETURN; 1161 | END; 1162 | 1163 | 1164 | -- do some calculations to get information for a guess at maxdop_limit. not using conditional code because this is nearly free to get 1165 | SELECT @MAXDOP_scheduler_limit = COUNT_BIG(*) 1166 | FROM sys.dm_os_schedulers 1167 | WHERE [status] = N'VISIBLE ONLINE'; 1168 | 1169 | -- not using effective_max_dop because I assume this DMV is empty on standard edition 1170 | SELECT @MAXDOP_RG_limit_guess = ISNULL(MAX(wg.max_dop), 0) 1171 | FROM sys.dm_exec_requests r 1172 | INNER JOIN sys.resource_governor_workload_groups wg ON r.group_id = wg.group_id 1173 | WHERE r.session_id = @@SPID; 1174 | 1175 | -- this is untested. I don't have access to standard edition 1176 | SET @MAXDOP_standard_edition_limit = CASE WHEN TRY_CAST(SERVERPROPERTY('EditionID') AS BIGINT) = -1534726760 THEN 2 ELSE 0 END; 1177 | 1178 | SELECT @MAXDOP_global_default = TRY_CAST(value_in_use AS SMALLINT) 1179 | FROM sys.configurations 1180 | WHERE [name] = N'max degree of parallelism'; 1181 | 1182 | 1183 | -- create a temp table to hold results of sys.dm_db_partition_stats dmv to avoid a not helpful spool that can appear 1184 | CREATE TABLE #pstats ( 1185 | [object_id] INT NOT NULL, 1186 | index_id INT NOT NULL, 1187 | partition_number INT NOT NULL, 1188 | sql_part_approx_row_count BIGINT NOT NULL, 1189 | sql_part_approx_bytes BIGINT NOT NULL, 1190 | sql_table_approx_row_count BIGINT NOT NULL, 1191 | sql_table_approx_bytes BIGINT NOT NULL, 1192 | sql_part_distance_from_rightmost_partition INT NOT NULL, 1193 | PRIMARY KEY ([object_id], index_id, partition_number) 1194 | ); 1195 | 1196 | -- create a temp table to hold results of sys.partitions dmv 1197 | CREATE TABLE #partitioned_indexes ( 1198 | [object_id] INT NOT NULL, 1199 | index_id INT NOT NULL, 1200 | PRIMARY KEY ([object_id], index_id) 1201 | ); 1202 | 1203 | 1204 | -- loop over all requested databases and populate CCI_Reorg_Rebuild_Partitions_To_Process work table 1205 | BEGIN TRANSACTION; 1206 | 1207 | EXEC sp_getapplock @Resource = N'UPDATE_CCI_REORG_REBUILD_TABLES', @LockMode = 'Exclusive'; 1208 | 1209 | DECLARE CCI_Databases CURSOR FOR 1210 | SELECT [database_id], [database_name] 1211 | FROM @CCI_Database_Names; 1212 | 1213 | OPEN CCI_Databases; 1214 | 1215 | FETCH NEXT FROM CCI_Databases INTO @current_CCI_database_id, @current_CCI_database_name; 1216 | 1217 | WHILE @@FETCH_STATUS = 0 1218 | BEGIN 1219 | -- get maxdop set at the database level 1220 | SET @MAXDOP_database_level_default = 0; 1221 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'SELECT @MAXDOP_database_level_default_OUT = TRY_CAST([value] AS SMALLINT) 1222 | FROM ' + QUOTENAME(@current_CCI_database_name) + N'.sys.database_scoped_configurations 1223 | WHERE [name] = N''MAXDOP'''; 1224 | 1225 | EXEC sp_executesql @dynamic_sql_max, 1226 | N'@MAXDOP_database_level_default_OUT SMALLINT OUTPUT', 1227 | @MAXDOP_database_level_default_OUT = @MAXDOP_database_level_default OUTPUT; 1228 | 1229 | -- best guess at maxdop limit (child job could be running under different workload group but it adjusts for that if needed) 1230 | SELECT @MAXDOP_calculated_at_database_level = MIN(maxdop_value) 1231 | FROM ( 1232 | VALUES 1233 | (COALESCE(@rebuild_MAXDOP, NULLIF(@MAXDOP_database_level_default, 0), NULLIF(@MAXDOP_global_default, 0), CASE WHEN @MAXDOP_scheduler_limit > 64 THEN 64 ELSE @MAXDOP_scheduler_limit END)), 1234 | (@MAXDOP_scheduler_limit), 1235 | (@MAXDOP_RG_limit_guess), 1236 | (@MAXDOP_standard_edition_limit) 1237 | ) v (maxdop_value) 1238 | WHERE v.maxdop_value <> 0; 1239 | 1240 | -- no lock hints because the code needs to find every index 1241 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'TRUNCATE TABLE #partitioned_indexes; 1242 | 1243 | INSERT INTO #partitioned_indexes 1244 | SELECT DISTINCT [object_id], index_id 1245 | FROM ' + QUOTENAME(@current_CCI_database_name) + N'.sys.partitions sp2 1246 | WHERE sp2.partition_number > 1; 1247 | 1248 | TRUNCATE TABLE #pstats; 1249 | 1250 | INSERT INTO #pstats ( 1251 | object_id 1252 | , index_id 1253 | , partition_number 1254 | , sql_part_approx_row_count 1255 | , sql_part_approx_bytes 1256 | , sql_table_approx_row_count 1257 | , sql_table_approx_bytes 1258 | , sql_part_distance_from_rightmost_partition 1259 | ) 1260 | SELECT 1261 | object_id 1262 | , index_id 1263 | , partition_number 1264 | , row_count sql_part_approx_row_count 1265 | , 8192 * reserved_page_count sql_part_approx_bytes 1266 | , SUM(row_count) OVER (PARTITION BY object_id, index_id) sql_table_approx_row_count 1267 | , SUM(8192 * reserved_page_count) OVER (PARTITION BY object_id, index_id) sql_table_approx_bytes 1268 | , ROW_NUMBER() OVER (PARTITION BY object_id, index_id ORDER BY partition_number DESC) sql_part_distance_from_rightmost_partition 1269 | FROM ' + QUOTENAME(@current_CCI_database_name) + N'.sys.dm_db_partition_stats 1270 | WHERE 1 = ' + CAST(@query_part_level_info AS NVARCHAR(1)) + '; 1271 | 1272 | INSERT INTO ' 1273 | + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Partitions_To_Process WITH (TABLOCK) 1274 | ([Database_Name] 1275 | , [Schema_Name] 1276 | , Table_Name 1277 | , Index_Name 1278 | , Partition_Number 1279 | , [Database_Id] 1280 | , [Object_Id] 1281 | , maxdop_limit 1282 | , partition_is_archive_compressed 1283 | , alter_last_attempt_time_utc 1284 | , alter_last_attempt_status_flag 1285 | , alter_last_attempt_was_rebuild 1286 | , alter_last_complete_time 1287 | , alter_last_partial_timeout_time_utc 1288 | , alter_last_full_timeout_time_utc 1289 | , alter_last_error_time 1290 | , sql_part_approx_row_count 1291 | , sql_part_approx_bytes 1292 | , sql_table_approx_row_count 1293 | , sql_table_approx_bytes 1294 | , sql_part_distance_from_rightmost_partition 1295 | , In_Progress) 1296 | SELECT 1297 | @current_CCI_database_name 1298 | , ss.name 1299 | , st.name 1300 | , si.name 1301 | , ca.partition_number_not_null 1302 | , @current_CCI_database_id 1303 | , st.[object_id] 1304 | , @MAXDOP_calculated_at_database_level 1305 | , CASE WHEN sp.data_compression = 4 THEN 1 ELSE 0 END partition_is_archive_compressed 1306 | , last_attempt.alter_last_attempt_time_utc 1307 | , last_attempt.alter_last_attempt_status_flag 1308 | , last_attempt.alter_last_attempt_was_rebuild 1309 | , alter_last_complete_time.alter_last_complete_time 1310 | , alter_last_partial_timeout_time_utc.alter_last_partial_timeout_time_utc 1311 | , alter_last_full_timeout_time_utc.alter_last_full_timeout_time_utc 1312 | , alter_last_error_time.alter_last_error_time 1313 | , pstats.sql_part_approx_row_count 1314 | , pstats.sql_part_approx_bytes 1315 | , pstats.sql_table_approx_row_count 1316 | , pstats.sql_table_approx_bytes 1317 | , pstats.sql_part_distance_from_rightmost_partition 1318 | , 0 1319 | FROM ' + QUOTENAME(@current_CCI_database_name) + N'.sys.indexes si 1320 | INNER JOIN ' + QUOTENAME(@current_CCI_database_name) + N'.sys.partitions sp ON si.[object_id] = sp.[object_id] AND si.index_id = sp.index_id 1321 | INNER JOIN ' + QUOTENAME(@current_CCI_database_name) + N'.sys.tables st ON si.[object_id] = st.[object_id] 1322 | INNER JOIN ' + QUOTENAME(@current_CCI_database_name) + N'.sys.schemas ss ON st.[schema_id] = ss.[schema_id] 1323 | LEFT OUTER JOIN ' + QUOTENAME(@current_CCI_database_name) + N'.sys.filegroups f ON f.data_space_id = si.data_space_id 1324 | LEFT OUTER JOIN ' + QUOTENAME(@current_CCI_database_name) + N'.sys.destination_data_spaces ds ON ds.partition_scheme_id = si.data_space_id AND ds.destination_id = sp.partition_number 1325 | LEFT OUTER JOIN ' + QUOTENAME(@current_CCI_database_name) + N'.sys.filegroups f2 ON f2.data_space_id = ds.data_space_id 1326 | LEFT OUTER JOIN #partitioned_indexes pi ON si.[object_id] = pi.[object_id] AND si.index_id = pi.index_id 1327 | CROSS APPLY ( 1328 | SELECT CASE WHEN pi.[object_id] IS NULL THEN -1 ELSE sp.partition_number END 1329 | ) ca (partition_number_not_null) 1330 | LEFT OUTER JOIN #pstats pstats WITH (FORCESEEK) ON 1 = ' + CAST(@query_part_level_info AS NVARCHAR(1)) + ' AND pstats.object_id = sp.object_id AND pstats.index_id = sp.index_id AND pstats.partition_number = sp.partition_number 1331 | OUTER APPLY ( 1332 | SELECT TOP (1) Alter_Start_Time_UTC alter_last_attempt_time_utc 1333 | , CASE 1334 | WHEN Did_Complete = 1 THEN 1 1335 | WHEN Did_Error = 1 THEN 4 1336 | WHEN Did_Stop = 1 AND Was_First_Alter_Of_Run = 1 THEN 2 1337 | WHEN Did_Stop = 1 AND Was_First_Alter_Of_Run = 0 THEN 3 1338 | ELSE NULL 1339 | END alter_last_attempt_status_flag 1340 | , Was_Rebuild alter_last_attempt_was_rebuild 1341 | FROM ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Index_History c WITH (FORCESEEK) 1342 | WHERE 1 = ' + CAST(@query_history_table AS NVARCHAR(1)) 1343 | + N' AND c.Was_First_Alter_Of_Run IN (0, 1) 1344 | AND c.Did_Complete IN (0, 1) 1345 | AND c.Did_Error IN (0, 1) 1346 | AND c.Did_Stop IN (0, 1) 1347 | AND c.Database_Name = @current_CCI_database_name 1348 | AND c.[Schema_Name] = ss.name COLLATE DATABASE_DEFAULT 1349 | AND c.Table_Name = st.name COLLATE DATABASE_DEFAULT 1350 | AND c.Index_Name = si.name COLLATE DATABASE_DEFAULT 1351 | AND c.Partition_Number = ca.partition_number_not_null 1352 | ORDER BY Alter_Start_Time_UTC DESC 1353 | ) last_attempt 1354 | 1355 | OUTER APPLY ( 1356 | SELECT TOP (1) Alter_Complete_Time_UTC alter_last_complete_time 1357 | FROM ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Index_History c WITH (FORCESEEK) 1358 | WHERE 1 = ' + CAST(@query_history_table AS NVARCHAR(1)) 1359 | + N' AND c.Was_First_Alter_Of_Run IN (0, 1) 1360 | AND c.Did_Complete IN (1) 1361 | AND c.Did_Error IN (0) 1362 | AND c.Did_Stop IN (0) 1363 | AND c.Database_Name = @current_CCI_database_name 1364 | AND c.[Schema_Name] = ss.name COLLATE DATABASE_DEFAULT 1365 | AND c.Table_Name = st.name COLLATE DATABASE_DEFAULT 1366 | AND c.Index_Name = si.name COLLATE DATABASE_DEFAULT 1367 | AND c.Partition_Number = ca.partition_number_not_null 1368 | ORDER BY Alter_Start_Time_UTC DESC 1369 | ) alter_last_complete_time 1370 | 1371 | OUTER APPLY ( 1372 | SELECT TOP (1) Alter_Stop_Time_UTC alter_last_partial_timeout_time_utc 1373 | FROM ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Index_History c WITH (FORCESEEK) 1374 | WHERE 1 = ' + CAST(@query_history_table AS NVARCHAR(1)) 1375 | + N' AND c.Was_First_Alter_Of_Run IN (0) 1376 | AND c.Did_Complete IN (0) 1377 | AND c.Did_Error IN (0) 1378 | AND c.Did_Stop IN (1) 1379 | AND c.Database_Name = @current_CCI_database_name 1380 | AND c.[Schema_Name] = ss.name COLLATE DATABASE_DEFAULT 1381 | AND c.Table_Name = st.name COLLATE DATABASE_DEFAULT 1382 | AND c.Index_Name = si.name COLLATE DATABASE_DEFAULT 1383 | AND c.Partition_Number = ca.partition_number_not_null 1384 | ORDER BY Alter_Start_Time_UTC DESC 1385 | ) alter_last_partial_timeout_time_utc 1386 | 1387 | OUTER APPLY ( 1388 | SELECT TOP (1) Alter_Stop_Time_UTC alter_last_full_timeout_time_utc 1389 | FROM ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Index_History c WITH (FORCESEEK) 1390 | WHERE 1 = ' + CAST(@query_history_table AS NVARCHAR(1)) 1391 | + N' AND c.Was_First_Alter_Of_Run IN (1) 1392 | AND c.Did_Complete IN (0) 1393 | AND c.Did_Error IN (0) 1394 | AND c.Did_Stop IN (1) 1395 | AND c.Database_Name = @current_CCI_database_name 1396 | AND c.[Schema_Name] = ss.name COLLATE DATABASE_DEFAULT 1397 | AND c.Table_Name = st.name COLLATE DATABASE_DEFAULT 1398 | AND c.Index_Name = si.name COLLATE DATABASE_DEFAULT 1399 | AND c.Partition_Number = ca.partition_number_not_null 1400 | ORDER BY Alter_Start_Time_UTC DESC 1401 | ) alter_last_full_timeout_time_utc 1402 | 1403 | OUTER APPLY ( 1404 | SELECT TOP (1) Alter_Stop_Time_UTC alter_last_error_time 1405 | FROM ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Index_History c WITH (FORCESEEK) 1406 | WHERE 1 = ' + CAST(@query_history_table AS NVARCHAR(1)) 1407 | + N' AND c.Was_First_Alter_Of_Run IN (0, 1) 1408 | AND c.Did_Complete IN (0) 1409 | AND c.Did_Error IN (1) 1410 | AND c.Did_Stop IN (1) 1411 | AND c.Database_Name = @current_CCI_database_name 1412 | AND c.[Schema_Name] = ss.name COLLATE DATABASE_DEFAULT 1413 | AND c.Table_Name = st.name COLLATE DATABASE_DEFAULT 1414 | AND c.Index_Name = si.name COLLATE DATABASE_DEFAULT 1415 | AND c.Partition_Number = ca.partition_number_not_null 1416 | ORDER BY Alter_Start_Time_UTC DESC 1417 | ) alter_last_error_time 1418 | 1419 | where si.type = 5 1420 | AND ISNULL(f.is_read_only, f2.is_read_only) = 0 ' 1421 | + CASE WHEN @ignore_archive_compressed_partitions = 1 THEN N'AND sp.data_compression = 3 ' ELSE N'' END 1422 | + N' AND NOT EXISTS ( 1423 | SELECT 1 1424 | FROM #CCI_Excluded_Schema_Names fs 1425 | WHERE fs.schema_name = ss.name COLLATE DATABASE_DEFAULT 1426 | ) 1427 | AND NOT EXISTS ( 1428 | SELECT 1 1429 | FROM #CCI_Excluded_Table_Names ft 1430 | WHERE ft.table_name = st.name COLLATE DATABASE_DEFAULT 1431 | ) 1432 | OPTION (NO_PERFORMANCE_SPOOL, USE HINT(''FORCE_DEFAULT_CARDINALITY_ESTIMATION''))'; 1433 | 1434 | EXEC sp_executesql @dynamic_sql_max, 1435 | N'@current_CCI_database_name SYSNAME, @current_CCI_database_id INT, @MAXDOP_calculated_at_database_level SMALLINT', 1436 | @current_CCI_database_name = @current_CCI_database_name, 1437 | @current_CCI_database_id = @current_CCI_database_id, 1438 | @MAXDOP_calculated_at_database_level = @MAXDOP_calculated_at_database_level; 1439 | 1440 | FETCH NEXT FROM CCI_Databases INTO @current_CCI_database_id, @current_CCI_database_name; 1441 | END; 1442 | 1443 | CLOSE CCI_Databases; 1444 | 1445 | DEALLOCATE CCI_Databases; 1446 | 1447 | -- create NCIs after all data has been inserted 1448 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'CREATE INDEX [NCI_String_Priority_Helper_' + SUBSTRING(CAST(RAND() AS NVARCHAR(10)), 3, 9) + N'] 1449 | ON ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Partitions_To_Process 1450 | (In_Progress, String_Priority_Helper, Partition_Number); 1451 | 1452 | CREATE INDEX [NCI_Database_Object_' + SUBSTRING(CAST(RAND() AS NVARCHAR(10)), 3, 9) + N'] 1453 | ON ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Partitions_To_Process 1454 | (Database_Id, Object_Id)'; 1455 | 1456 | EXEC sp_executesql @dynamic_sql_max; 1457 | 1458 | EXEC sp_releaseapplock @Resource = N'UPDATE_CCI_REORG_REBUILD_TABLES'; 1459 | 1460 | COMMIT TRANSACTION; 1461 | 1462 | 1463 | -- create and populate a work table of distinct database_name, database_id, and object_id for child jobs to use as queue 1464 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'DROP TABLE IF EXISTS ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Tables_To_Process; 1465 | CREATE TABLE ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Tables_To_Process ( 1466 | Database_Name SYSNAME NOT NULL, 1467 | Database_Id INT NOT NULL, 1468 | Object_Id INT NOT NULL, 1469 | Single_Partition_Only BIT NOT NULL 1470 | )'; 1471 | 1472 | EXEC sp_executesql @dynamic_sql_max; 1473 | 1474 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'INSERT INTO ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Tables_To_Process 1475 | WITH (TABLOCKX) 1476 | (Database_Name, Database_Id, Object_Id, Single_Partition_Only) 1477 | SELECT Database_Name, Database_Id, Object_Id, MAX(CASE WHEN Partition_Number = -1 THEN 1 ELSE 0 END) Single_Partition_Only 1478 | FROM ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Partitions_To_Process 1479 | GROUP BY Database_Name, Database_Id, Object_Id'; 1480 | 1481 | EXEC sp_executesql @dynamic_sql_max; 1482 | 1483 | 1484 | EXEC [dbo].AgentJobMultiThread_CreateAgentJobs 1485 | @workload_identifier = @workload_identifier, 1486 | @logging_database_name = @logging_database_name, 1487 | @logging_schema_name = @logging_schema_name, 1488 | @parent_start_time = @parent_start_time, 1489 | @child_stored_procedure_name = @child_stored_procedure_name, 1490 | @cleanup_stored_procedure_name = @cleanup_stored_procedure_name, 1491 | @max_minutes_to_run = @max_minutes_to_run, 1492 | @job_prefix = @job_prefix, 1493 | @total_jobs_to_create = @max_CCI_alter_job_count; 1494 | 1495 | END; 1496 | 1497 | GO 1498 | 1499 | 1500 | 1501 | 1502 | 1503 | 1504 | 1505 | CREATE OR ALTER PROCEDURE [dbo].[CCI_Reorg_Rebuild_Child_Job] ( 1506 | @logging_database_name SYSNAME, 1507 | @logging_schema_name SYSNAME, 1508 | @parent_start_time DATETIME2, 1509 | @job_number SMALLINT, 1510 | @job_attempt_number SMALLINT 1511 | ) 1512 | AS 1513 | BEGIN 1514 | /* 1515 | Procedure Name: CCI_Reorg_Rebuild_Child_Job 1516 | Author: Joe Obbish 1517 | Version: 1.0 1518 | Updates: https://github.com/jobbish-sql/SQL-Server-Multi-Thread 1519 | License: MIT 1520 | Purpose: To be called by the multithreading job framework. You should not be executing this stored procedure yourself. 1521 | */ 1522 | DECLARE @workload_identifier NVARCHAR(50) = N'CCI_Reorg_Rebuild', 1523 | @child_stored_procedure_name SYSNAME = N'CCI_Reorg_Rebuild_Child_Job', 1524 | @all_partitions_processed BIT = 0, 1525 | @all_tables_processed BIT = 0, 1526 | @database_name SYSNAME, 1527 | @database_id INT, 1528 | @schema_name SYSNAME, 1529 | @table_name SYSNAME, 1530 | @object_id INT, 1531 | @index_name SYSNAME, 1532 | @partition_number INT, 1533 | @string_priority_helper VARCHAR(58), 1534 | @calculated_priority NUMERIC(38, 0), 1535 | @calculated_do_REBUILD BIT, 1536 | @Single_Partition_Only BIT, 1537 | @reorg_execute_twice BIT, 1538 | @alter_sql NVARCHAR(4000), 1539 | @dynamic_sql_max NVARCHAR(MAX) = CAST(N'' AS NVARCHAR(MAX)), 1540 | @dynamic_sql_result_set_exists BIT, 1541 | @parm_definition NVARCHAR(4000), 1542 | @first_alter BIT = 1, 1543 | @cpu_time_snapshot INT, 1544 | @cpu_time_delta INT, 1545 | @alter_start_time DATETIME2, 1546 | @error_message NVARCHAR(4000), 1547 | @reorg_use_COMPRESS_ALL_ROWGROUPS_option BIT, 1548 | @rebuild_MAXDOP INT, 1549 | @rebuild_ONLINE_option BIT, 1550 | @used_SQL_expression_for_partition_priority_calculation NVARCHAR(4000), 1551 | @used_SQL_expression_for_rebuild_calculation NVARCHAR(4000), 1552 | @was_job_rescheduled BIT, 1553 | @disable_CPU_rescheduling BIT, 1554 | @job_prefix NVARCHAR(20), 1555 | @prioritization_only BIT, 1556 | @query_CCI_DMV_info BIT, 1557 | @MAXDOP_RG_limit SMALLINT, 1558 | @should_job_stop BIT; 1559 | 1560 | SET NOCOUNT ON; 1561 | 1562 | -- get needed parameter values from the summary table for this run 1563 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'SELECT 1564 | @reorg_use_COMPRESS_ALL_ROWGROUPS_option_OUT = Reorg_Use_COMPRESS_ALL_ROWGROUPS_Option 1565 | , @reorg_execute_twice_OUT = Reorg_Execute_Twice 1566 | , @used_SQL_expression_for_partition_priority_calculation_OUT = Used_SQL_Expression_For_Partition_Priority_Calculation 1567 | , @used_SQL_expression_for_rebuild_calculation_OUT = Used_SQL_Expression_For_Rebuild_Calculation 1568 | , @rebuild_MAXDOP_OUT = Rebuild_MAXDOP 1569 | , @rebuild_ONLINE_option_OUT = Rebuild_ONLINE_Option 1570 | , @disable_CPU_rescheduling_OUT = Disable_CPU_Rescheduling 1571 | , @used_job_prefix_OUT = Used_Job_Prefix 1572 | , @prioritization_only_OUT = Prioritization_Only 1573 | , @query_CCI_DMV_info_OUT = query_CCI_DMV_info 1574 | FROM ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Summary 1575 | WHERE Summary_Start_Time_UTC = @parent_start_time'; 1576 | 1577 | SET @parm_definition = N'@reorg_use_COMPRESS_ALL_ROWGROUPS_option_OUT BIT OUTPUT, @reorg_execute_twice_OUT BIT OUTPUT, @used_SQL_expression_for_partition_priority_calculation_OUT NVARCHAR(4000) OUTPUT' 1578 | + N',@used_SQL_expression_for_rebuild_calculation_OUT NVARCHAR(4000) OUTPUT, @rebuild_MAXDOP_OUT INT OUTPUT, @rebuild_ONLINE_option_OUT BIT OUTPUT' 1579 | + N', @disable_CPU_rescheduling_OUT BIT OUTPUT, @used_job_prefix_OUT NVARCHAR(100) OUTPUT, @prioritization_only_OUT BIT OUTPUT, @query_CCI_DMV_info_OUT BIT OUTPUT, @parent_start_time DATETIME2'; 1580 | 1581 | EXEC sp_executesql @dynamic_sql_max, 1582 | @parm_definition, 1583 | @reorg_use_COMPRESS_ALL_ROWGROUPS_option_OUT = @reorg_use_COMPRESS_ALL_ROWGROUPS_option OUTPUT, 1584 | @reorg_execute_twice_OUT = @reorg_execute_twice OUTPUT, 1585 | @used_SQL_expression_for_partition_priority_calculation_OUT = @used_SQL_expression_for_partition_priority_calculation OUTPUT, 1586 | @used_SQL_expression_for_rebuild_calculation_OUT = @used_SQL_expression_for_rebuild_calculation OUTPUT, 1587 | @rebuild_MAXDOP_OUT = @rebuild_MAXDOP OUTPUT, 1588 | @rebuild_ONLINE_option_OUT = @rebuild_ONLINE_option OUTPUT, 1589 | @disable_CPU_rescheduling_OUT = @disable_CPU_rescheduling OUTPUT, 1590 | @used_job_prefix_OUT = @job_prefix OUTPUT, 1591 | @prioritization_only_OUT = @prioritization_only OUTPUT, 1592 | @query_CCI_DMV_info_OUT = @query_CCI_DMV_info OUTPUT, 1593 | @parent_start_time = @parent_start_time; 1594 | 1595 | -- there was likely a problem with the parent procedure if this is NULL 1596 | IF @reorg_use_COMPRESS_ALL_ROWGROUPS_option IS NULL 1597 | BEGIN 1598 | THROW 60000, 'Cannot find expected row in CCI_Reorg_Rebuild_Summary table. Look for an error logged by the CCIReorgAndRebuild stored procedure.', 1; 1599 | RETURN; 1600 | END; 1601 | 1602 | 1603 | IF @disable_CPU_rescheduling = 0 1604 | BEGIN 1605 | EXEC dbo.AgentJobMultiThread_RescheduleChildJobIfNeeded 1606 | @workload_identifier = @workload_identifier, 1607 | @logging_database_name = @logging_database_name, 1608 | @logging_schema_name = @logging_schema_name, 1609 | @parent_start_time = @parent_start_time, 1610 | @child_stored_procedure_name = @child_stored_procedure_name, 1611 | @job_prefix = @job_prefix, 1612 | @job_number = @job_number, 1613 | @job_attempt_number = @job_attempt_number, 1614 | @was_job_rescheduled_OUT = @was_job_rescheduled OUTPUT; 1615 | 1616 | IF @was_job_rescheduled = 1 1617 | BEGIN 1618 | RETURN; 1619 | END; 1620 | END; 1621 | 1622 | 1623 | -- target table for sys.dm_db_column_store_row_group_physical_stats 1624 | CREATE TABLE #cci_dmv_results ( 1625 | Partition_Number INT NOT NULL, 1626 | cci_part_row_count BIGINT NULL, 1627 | cci_part_open_row_count BIGINT NULL, 1628 | cci_part_compressed_row_count BIGINT NULL, 1629 | cci_part_deleted_row_count BIGINT NULL, 1630 | cci_part_closed_row_count BIGINT NULL, 1631 | cci_part_tombstone_row_count BIGINT NULL, 1632 | cci_part_dict_pressure_row_count BIGINT NULL, 1633 | cci_part_memory_pressure_row_count BIGINT NULL, 1634 | cci_part_rowgroup_count BIGINT NULL, 1635 | cci_part_open_rowgroup_count BIGINT NULL, 1636 | cci_part_compressed_rowgroup_count BIGINT NULL, 1637 | cci_part_closed_rowgroup_count BIGINT NULL, 1638 | cci_part_tombstone_rowgroup_count BIGINT NULL, 1639 | cci_part_compressed_rowgroup_count_under_17k_rows BIGINT NULL, 1640 | cci_part_compressed_rowgroup_count_under_132k_rows BIGINT NULL, 1641 | cci_part_compressed_rowgroup_count_under_263k_rows BIGINT NULL, 1642 | cci_part_compressed_rowgroup_count_under_525k_rows BIGINT NULL, 1643 | cci_part_dict_pressure_rowgroup_count BIGINT NULL, 1644 | cci_part_memory_pressure_rowgroup_count BIGINT NULL, 1645 | cci_part_approx_deleted_rows_bytes BIGINT NULL, 1646 | cci_part_approx_compressed_bytes BIGINT NULL, 1647 | cci_part_approx_uncompressed_bytes BIGINT NULL, 1648 | cci_part_total_bytes BIGINT NULL, 1649 | cci_table_total_bytes BIGINT NULL, 1650 | cci_table_row_count BIGINT NULL, 1651 | cci_table_open_row_count BIGINT NULL, 1652 | cci_table_compressed_row_count BIGINT NULL, 1653 | cci_table_deleted_row_count BIGINT NULL, 1654 | cci_table_closed_row_count BIGINT NULL, 1655 | cci_table_tombstone_row_count BIGINT NULL 1656 | ); 1657 | 1658 | 1659 | -- need to check this here again in case the parent procedure was running in a different workload group than this session 1660 | SELECT @MAXDOP_RG_limit = ISNULL(MAX(wg.max_dop), 0) 1661 | FROM sys.dm_exec_requests r 1662 | INNER JOIN sys.resource_governor_workload_groups wg ON r.group_id = wg.group_id 1663 | WHERE r.session_id = @@SPID; 1664 | 1665 | 1666 | SET @should_job_stop = 0; 1667 | -- loop through tables and set needed columns in CCI_Reorg_Rebuild_Partitions_To_Process 1668 | WHILE @all_tables_processed = 0 1669 | BEGIN 1670 | SET @database_name = NULL; 1671 | SET @database_id = NULL; 1672 | SET @object_id = NULL; 1673 | SET @Single_Partition_Only = NULL; 1674 | 1675 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'DECLARE @hold_deleted_row TABLE ( 1676 | Database_Name SYSNAME, 1677 | Database_Id INT, 1678 | Object_Id INT, 1679 | Single_Partition_Only BIT 1680 | ); 1681 | 1682 | DELETE TOP (1) FROM ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Tables_To_Process 1683 | WITH (TABLOCKX) 1684 | OUTPUT deleted.Database_Name, deleted.Database_Id, deleted.Object_Id, deleted.Single_Partition_Only INTO @hold_deleted_row; 1685 | 1686 | SELECT @database_name_OUT = Database_Name 1687 | , @database_id_OUT = Database_Id 1688 | , @object_id_OUT = Object_Id 1689 | , @single_partition_only_OUT = Single_Partition_Only 1690 | FROM @hold_deleted_row'; 1691 | 1692 | EXEC sp_executesql @dynamic_sql_max, 1693 | N'@database_name_OUT SYSNAME OUTPUT, @database_id_OUT INT OUTPUT, @object_id_OUT INT OUTPUT, @single_partition_only_OUT BIT OUTPUT', 1694 | @database_name_OUT = @database_name OUTPUT, 1695 | @database_id_OUT = @database_id OUTPUT, 1696 | @object_id_OUT = @object_id OUTPUT, 1697 | @single_partition_only_OUT = @Single_Partition_Only OUTPUT; 1698 | 1699 | -- if NULL then there are no more rows for this child job to process from the table 1700 | IF @database_name IS NOT NULL 1701 | BEGIN 1702 | -- querying sys.dm_db_column_store_row_group_physical_stats can be expensive, so only query at the object level and only if it contains a needed column for the algorithms 1703 | IF @query_CCI_DMV_info = 1 1704 | BEGIN 1705 | TRUNCATE TABLE #cci_dmv_results; 1706 | 1707 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'INSERT INTO #cci_dmv_results 1708 | ( 1709 | Partition_Number 1710 | , cci_part_row_count 1711 | , cci_part_open_row_count 1712 | , cci_part_compressed_row_count 1713 | , cci_part_deleted_row_count 1714 | , cci_part_closed_row_count 1715 | , cci_part_tombstone_row_count 1716 | , cci_part_dict_pressure_row_count 1717 | , cci_part_memory_pressure_row_count 1718 | , cci_part_rowgroup_count 1719 | , cci_part_open_rowgroup_count 1720 | , cci_part_compressed_rowgroup_count 1721 | , cci_part_closed_rowgroup_count 1722 | , cci_part_tombstone_rowgroup_count 1723 | , cci_part_compressed_rowgroup_count_under_17k_rows 1724 | , cci_part_compressed_rowgroup_count_under_132k_rows 1725 | , cci_part_compressed_rowgroup_count_under_263k_rows 1726 | , cci_part_compressed_rowgroup_count_under_525k_rows 1727 | , cci_part_dict_pressure_rowgroup_count 1728 | , cci_part_memory_pressure_rowgroup_count 1729 | , cci_part_approx_deleted_rows_bytes 1730 | , cci_part_approx_compressed_bytes 1731 | , cci_part_approx_uncompressed_bytes 1732 | , cci_part_total_bytes 1733 | , cci_table_total_bytes 1734 | , cci_table_row_count 1735 | , cci_table_open_row_count 1736 | , cci_table_compressed_row_count 1737 | , cci_table_deleted_row_count 1738 | , cci_table_closed_row_count 1739 | , cci_table_tombstone_row_count 1740 | ) 1741 | SELECT q.* 1742 | , SUM(cci_part_total_bytes) OVER () cci_table_total_bytes 1743 | , SUM(cci_part_row_count) OVER () cci_table_row_count 1744 | , SUM(cci_part_open_row_count) OVER () cci_table_open_row_count 1745 | , SUM(cci_part_compressed_row_count) OVER () cci_table_compressed_row_count 1746 | , SUM(cci_part_deleted_row_count) OVER () cci_table_deleted_row_count 1747 | , SUM(cci_part_closed_row_count) OVER () cci_table_closed_row_count 1748 | , SUM(cci_part_tombstone_row_count) OVER () cci_table_tombstone_row_count 1749 | FROM 1750 | ( 1751 | SELECT 1752 | ' + CASE WHEN @Single_Partition_Only = 1 THEN N'-1' ELSE N'' END + N' Partition_Number 1753 | , SUM(total_rows) cci_part_row_count 1754 | , SUM(CASE WHEN state = 1 THEN total_rows ELSE 0 END) cci_part_open_row_count 1755 | , SUM(CASE WHEN state = 3 THEN total_rows ELSE 0 END) cci_part_compressed_row_count 1756 | , SUM(deleted_rows) cci_part_deleted_row_count 1757 | , SUM(CASE WHEN state = 2 THEN total_rows ELSE 0 END) cci_part_closed_row_count 1758 | , SUM(CASE WHEN state = 4 THEN total_rows ELSE 0 END) cci_part_tombstone_row_count 1759 | , SUM(CASE WHEN trim_reason = 4 THEN total_rows ELSE 0 END) cci_part_dict_pressure_row_count 1760 | , SUM(CASE WHEN trim_reason = 5 THEN total_rows ELSE 0 END) cci_part_memory_pressure_row_count 1761 | , COUNT_BIG(*) cci_part_rowgroup_count 1762 | , SUM(CASE WHEN state = 1 THEN 1 ELSE 0 END) cci_part_open_rowgroup_count 1763 | , SUM(CASE WHEN state = 3 THEN 1 ELSE 0 END) cci_part_compressed_rowgroup_count 1764 | , SUM(CASE WHEN state = 2 THEN 1 ELSE 0 END) cci_part_closed_rowgroup_count 1765 | , SUM(CASE WHEN state = 4 THEN 1 ELSE 0 END) cci_part_tombstone_rowgroup_count 1766 | , SUM(CASE WHEN state = 3 AND total_rows < 17000 THEN 1 ELSE 0 END) cci_part_compressed_rowgroup_count_under_17k_rows 1767 | , SUM(CASE WHEN state = 3 AND total_rows < 132000 THEN 1 ELSE 0 END) cci_part_compressed_rowgroup_count_under_132k_rows 1768 | , SUM(CASE WHEN state = 3 AND total_rows < 263000 THEN 1 ELSE 0 END) cci_part_compressed_rowgroup_count_under_263k_rows 1769 | , SUM(CASE WHEN state = 3 AND total_rows < 525000 THEN 1 ELSE 0 END) cci_part_compressed_rowgroup_count_under_525k_rows 1770 | , SUM(CASE WHEN trim_reason = 4 THEN 1 ELSE 0 END) cci_part_dict_pressure_rowgroup_count 1771 | , SUM(CASE WHEN trim_reason = 5 THEN 1 ELSE 0 END) cci_part_memory_pressure_rowgroup_count 1772 | , SUM(CASE WHEN total_rows = 0 THEN 0 ELSE 1.0 * size_in_bytes * deleted_rows / total_rows END) cci_part_approx_deleted_rows_bytes 1773 | , SUM(CASE WHEN total_rows = 0 OR state <> 3 THEN 0 ELSE 1.0 * size_in_bytes * (total_rows - deleted_rows) / total_rows END) cci_part_approx_compressed_bytes 1774 | , SUM(CASE WHEN state IN (1, 2) THEN size_in_bytes ELSE 0 END) cci_part_approx_uncompressed_bytes 1775 | , SUM(size_in_bytes) cci_part_total_bytes 1776 | FROM ' + QUOTENAME(@database_name) + N'.sys.dm_db_column_store_row_group_physical_stats 1777 | WHERE object_id = @object_id 1778 | GROUP BY Partition_Number 1779 | ) q'; 1780 | 1781 | EXEC sp_executesql @dynamic_sql_max, 1782 | N'@object_id INT', 1783 | @object_id = @object_id; 1784 | 1785 | END; 1786 | 1787 | BEGIN TRANSACTION; 1788 | EXEC sp_getapplock @Resource = N'UPDATE_CCI_REORG_REBUILD_TABLES', @LockMode = 'Exclusive'; 1789 | 1790 | IF @query_CCI_DMV_info = 1 1791 | BEGIN 1792 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'UPDATE t SET 1793 | t.maxdop_limit = CASE WHEN @MAXDOP_RG_limit > 0 AND maxdop_limit > @MAXDOP_RG_limit THEN @MAXDOP_RG_limit ELSE t.maxdop_limit END 1794 | , t.cci_part_row_count = s.cci_part_row_count 1795 | , t.cci_part_open_row_count = s.cci_part_open_row_count 1796 | , t.cci_part_compressed_row_count = s.cci_part_compressed_row_count 1797 | , t.cci_part_deleted_row_count = s.cci_part_deleted_row_count 1798 | , t.cci_part_closed_row_count = s.cci_part_closed_row_count 1799 | , t.cci_part_tombstone_row_count = s.cci_part_tombstone_row_count 1800 | , t.cci_part_dict_pressure_row_count = s.cci_part_dict_pressure_row_count 1801 | , t.cci_part_memory_pressure_row_count = s.cci_part_memory_pressure_row_count 1802 | , t.cci_part_rowgroup_count = s.cci_part_rowgroup_count 1803 | , t.cci_part_open_rowgroup_count = s.cci_part_open_rowgroup_count 1804 | , t.cci_part_compressed_rowgroup_count = s.cci_part_compressed_rowgroup_count 1805 | , t.cci_part_closed_rowgroup_count = s.cci_part_closed_rowgroup_count 1806 | , t.cci_part_tombstone_rowgroup_count = s.cci_part_tombstone_rowgroup_count 1807 | , t.cci_part_compressed_rowgroup_count_under_17k_rows = s.cci_part_compressed_rowgroup_count_under_17k_rows 1808 | , t.cci_part_compressed_rowgroup_count_under_132k_rows = s.cci_part_compressed_rowgroup_count_under_132k_rows 1809 | , t.cci_part_compressed_rowgroup_count_under_263k_rows = s.cci_part_compressed_rowgroup_count_under_263k_rows 1810 | , t.cci_part_compressed_rowgroup_count_under_525k_rows = s.cci_part_compressed_rowgroup_count_under_525k_rows 1811 | , t.cci_part_dict_pressure_rowgroup_count = s.cci_part_dict_pressure_rowgroup_count 1812 | , t.cci_part_memory_pressure_rowgroup_count = s.cci_part_memory_pressure_rowgroup_count 1813 | , t.cci_part_approx_deleted_rows_bytes = s.cci_part_approx_deleted_rows_bytes 1814 | , t.cci_part_approx_compressed_bytes = s.cci_part_approx_compressed_bytes 1815 | , t.cci_part_approx_uncompressed_bytes = s.cci_part_approx_uncompressed_bytes 1816 | , t.cci_part_total_bytes = s.cci_part_total_bytes 1817 | , t.cci_table_total_bytes = s.cci_table_total_bytes 1818 | , t.cci_table_row_count = s.cci_table_row_count 1819 | , t.cci_table_open_row_count = s.cci_table_open_row_count 1820 | , t.cci_table_compressed_row_count = s.cci_table_compressed_row_count 1821 | , t.cci_table_deleted_row_count = s.cci_table_deleted_row_count 1822 | , t.cci_table_closed_row_count = s.cci_table_closed_row_count 1823 | , t.cci_table_tombstone_row_count = s.cci_table_tombstone_row_count 1824 | FROM ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Partitions_To_Process t 1825 | INNER JOIN #cci_dmv_results s ON t.Partition_Number = s.Partition_Number 1826 | WHERE t.Database_Id = @database_id AND t.Object_Id = @object_id'; 1827 | 1828 | EXEC sp_executesql @dynamic_sql_max, 1829 | N'@database_id INT, @object_id INT, @MAXDOP_RG_limit SMALLINT', 1830 | @database_id = @database_id, 1831 | @object_id = @object_id, 1832 | @MAXDOP_RG_limit = @MAXDOP_RG_limit; 1833 | END 1834 | ELSE IF @MAXDOP_RG_limit <> 0 1835 | BEGIN 1836 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'UPDATE t SET t.maxdop_limit = @MAXDOP_RG_limit 1837 | FROM ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Partitions_To_Process t 1838 | WHERE t.Database_Id = @database_id AND t.Object_Id = @object_id 1839 | AND maxdop_limit > @MAXDOP_RG_limit'; 1840 | 1841 | EXEC sp_executesql @dynamic_sql_max, 1842 | N'@database_id INT, @object_id INT, @MAXDOP_RG_limit SMALLINT', 1843 | @database_id = @database_id, 1844 | @object_id = @object_id, 1845 | @MAXDOP_RG_limit = @MAXDOP_RG_limit; 1846 | END; 1847 | 1848 | -- calculate priority and rebuild vs reorg after all other columns are set 1849 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'UPDATE ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Partitions_To_Process 1850 | SET 1851 | Calculated_Priority = ' + @used_SQL_expression_for_partition_priority_calculation + N' 1852 | , Job_Number_That_Calculated_Priority = @job_number 1853 | , Prioritization_Complete_Time_UTC = SYSUTCDATETIME() 1854 | , In_Progress = CASE WHEN ' + @used_SQL_expression_for_partition_priority_calculation + ' = 0 THEN -1 ELSE In_Progress END 1855 | , Calculated_Do_REBUILD = ' + @used_SQL_expression_for_rebuild_calculation + 1856 | N' WHERE Database_Id = @database_id AND Object_Id = @object_id'; 1857 | 1858 | EXEC sp_executesql @dynamic_sql_max, 1859 | N'@job_number SMALLINT, @database_id INT, @object_id INT', 1860 | @job_number = @job_number, 1861 | @database_id = @database_id, 1862 | @object_id = @object_id; 1863 | 1864 | EXEC sp_releaseapplock @Resource = N'UPDATE_CCI_REORG_REBUILD_TABLES'; 1865 | COMMIT TRANSACTION; 1866 | 1867 | 1868 | EXEC [dbo].AgentJobMultiThread_ShouldChildJobHalt 1869 | @workload_identifier = @workload_identifier, 1870 | @logging_database_name = @logging_database_name, 1871 | @logging_schema_name = @logging_schema_name, 1872 | @parent_start_time = @parent_start_time, 1873 | @should_job_halt_OUT = @should_job_stop OUTPUT; 1874 | 1875 | IF @should_job_stop = 1 1876 | BEGIN 1877 | RETURN; 1878 | END; 1879 | END 1880 | ELSE 1881 | BEGIN -- @database_name can only be null if there are no more rows for this job to process 1882 | SET @all_tables_processed = 1; 1883 | END; 1884 | 1885 | END; 1886 | 1887 | -- don't do any maintenance operations if end user just wants prioritization 1888 | IF @prioritization_only = 1 1889 | BEGIN 1890 | RETURN; 1891 | END; 1892 | 1893 | 1894 | -- loop through all partitions that need a maintenance action 1895 | WHILE @all_partitions_processed = 0 1896 | BEGIN 1897 | SET @database_name = NULL; 1898 | SET @schema_name = NULL; 1899 | SET @table_name = NULL; 1900 | SET @index_name = NULL; 1901 | SET @partition_number = NULL; 1902 | SET @string_priority_helper = NULL; 1903 | SET @calculated_do_REBUILD = NULL; 1904 | SET @calculated_priority = NULL; 1905 | 1906 | BEGIN TRANSACTION; 1907 | EXEC sp_getapplock @Resource = N'UPDATE_CCI_REORG_REBUILD_TABLES', @LockMode = 'Exclusive'; 1908 | 1909 | -- this is the easy way to write it, believe it or not 1910 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'WITH ConsultantBux 1911 | AS 1912 | ( 1913 | SELECT TOP (1) 1914 | wt.[Database_Name] 1915 | , wt.[Schema_Name] 1916 | , wt.Table_Name 1917 | , wt.Index_Name 1918 | , wt.Partition_Number 1919 | , wt.String_Priority_Helper 1920 | , wt.Calculated_Do_REBUILD 1921 | , wt.Calculated_Priority 1922 | FROM ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Partitions_To_Process wt 1923 | WHERE wt.In_Progress = 0 1924 | AND wt.Calculated_Priority > 0 1925 | ORDER BY wt.String_Priority_Helper DESC, wt.Partition_Number DESC 1926 | 1927 | UNION ALL 1928 | 1929 | SELECT 1930 | R.[Database_Name] 1931 | , R.[Schema_Name] 1932 | , R.Table_Name 1933 | , R.Index_Name 1934 | , R.Partition_Number 1935 | , R.String_Priority_Helper 1936 | , R.Calculated_Do_REBUILD 1937 | , R.Calculated_Priority 1938 | FROM 1939 | ( 1940 | SELECT 1941 | wt2.[Database_Name] 1942 | , wt2.[Schema_Name] 1943 | , wt2.Table_Name 1944 | , wt2.Index_Name 1945 | , wt2.Partition_Number 1946 | , wt2.String_Priority_Helper 1947 | , wt2.Calculated_Do_REBUILD 1948 | , wt2.Calculated_Priority 1949 | , rn = ROW_NUMBER() OVER (ORDER BY wt2.String_Priority_Helper DESC) 1950 | FROM ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Partitions_To_Process AS wt2 WITH (FORCESEEK) 1951 | INNER JOIN ConsultantBux AS R 1952 | ON R.String_Priority_Helper > wt2.String_Priority_Helper 1953 | WHERE wt2.In_Progress = 0 1954 | AND wt2.Calculated_Priority > 0 1955 | ) AS R 1956 | WHERE R.rn = 1 1957 | ) 1958 | SELECT TOP (1) 1959 | @database_name_OUT = c.[Database_Name] 1960 | , @schema_name_OUT = c.[Schema_Name] 1961 | , @table_name_OUT = c.Table_Name 1962 | , @index_name_OUT = c.Index_Name 1963 | , @partition_number_OUT = c.Partition_Number 1964 | , @string_priority_helper_OUT = c.String_Priority_Helper 1965 | , @calculated_do_REBUILD_OUT = c.Calculated_Do_REBUILD 1966 | , @calculated_priority_OUT = c.Calculated_Priority 1967 | FROM ConsultantBux c 1968 | WHERE NOT EXISTS ( 1969 | SELECT 1 1970 | FROM ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Partitions_To_Process wt WITH (FORCESEEK) 1971 | WHERE wt.In_Progress = 1 1972 | AND wt.[Database_Name] = c.[Database_Name] AND wt.[Schema_Name] = c.[Schema_Name] AND wt.Table_Name = c.Table_Name 1973 | ) 1974 | OPTION (MAXRECURSION 0, USE HINT(''FORCE_DEFAULT_CARDINALITY_ESTIMATION''))'; 1975 | 1976 | SET @parm_definition = N'@database_name_OUT SYSNAME OUTPUT, @schema_name_OUT SYSNAME OUTPUT, @table_name_OUT SYSNAME OUTPUT, @index_name_OUT SYSNAME OUTPUT' 1977 | + N', @partition_number_OUT INT OUTPUT, @string_priority_helper_OUT VARCHAR(58) OUTPUT, @calculated_do_REBUILD_OUT BIT OUTPUT, @calculated_priority_OUT NUMERIC(38, 0) OUTPUT'; 1978 | 1979 | EXEC sp_executesql @dynamic_sql_max, 1980 | @parm_definition, 1981 | @database_name_OUT = @database_name OUTPUT, 1982 | @schema_name_OUT = @schema_name OUTPUT, 1983 | @table_name_OUT = @table_name OUTPUT, 1984 | @index_name_OUT = @index_name OUTPUT, 1985 | @partition_number_OUT = @partition_number OUTPUT, 1986 | @string_priority_helper_OUT = @string_priority_helper OUTPUT, 1987 | @calculated_do_REBUILD_OUT = @calculated_do_REBUILD OUTPUT, 1988 | @calculated_priority_OUT = @calculated_priority OUTPUT; 1989 | 1990 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'UPDATE ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Partitions_To_Process 1991 | SET In_Progress = 1 1992 | , Job_Number_That_Attempted_Alter = @job_number 1993 | WHERE [Database_Name] = @database_name 1994 | AND [Schema_Name] = @schema_name 1995 | AND [Table_Name] = @table_name 1996 | AND Index_Name = @index_name 1997 | AND Partition_Number = @partition_number 1998 | AND In_Progress = 0 1999 | AND String_Priority_Helper = @string_priority_helper'; 2000 | 2001 | EXEC sp_executesql @dynamic_sql_max, 2002 | N'@job_number SMALLINT, @database_name SYSNAME, @schema_name SYSNAME, @table_name SYSNAME, @index_name SYSNAME, @partition_number INT, @string_priority_helper VARCHAR(58)', 2003 | @job_number = @job_number, 2004 | @database_name = @database_name, 2005 | @schema_name = @schema_name, 2006 | @table_name = @table_name, 2007 | @index_name = @index_name, 2008 | @partition_number = @partition_number, 2009 | @string_priority_helper = @string_priority_helper; 2010 | 2011 | EXEC sp_releaseapplock @Resource = N'UPDATE_CCI_REORG_REBUILD_TABLES'; 2012 | COMMIT TRANSACTION; 2013 | 2014 | -- if database is NULL then there is no longer any work for this session to do 2015 | IF @database_name IS NOT NULL 2016 | BEGIN 2017 | BEGIN TRANSACTION; 2018 | EXEC sp_getapplock @Resource = N'UPDATE_CCI_REORG_REBUILD_TABLES', @LockMode = 'Exclusive'; 2019 | 2020 | SET @alter_start_time = SYSUTCDATETIME(); 2021 | 2022 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'INSERT INTO ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Index_History 2023 | (Summary_Start_Time_UTC, Job_Number, [Database_Name], [Schema_Name], Table_Name, Index_Name, Partition_Number, Alter_Start_Time_UTC, Session_Id, Was_First_Alter_Of_Run, Was_Rebuild, Calculated_Priority) 2024 | VALUES 2025 | (@parent_start_time, @job_number, @database_name, @schema_name, @table_name, @index_name, @partition_number, @alter_start_time, @@SPID, @first_alter, @calculated_do_REBUILD, @calculated_priority)'; 2026 | 2027 | SET @parm_definition = N'@parent_start_time DATETIME2, @job_number SMALLINT, @database_name SYSNAME, @schema_name SYSNAME, @table_name SYSNAME, @index_name SYSNAME' 2028 | + N', @partition_number INT, @alter_start_time DATETIME2, @first_alter BIT, @calculated_do_REBUILD BIT, @calculated_priority NUMERIC(38, 0)'; 2029 | 2030 | EXEC sp_executesql @dynamic_sql_max, 2031 | @parm_definition, 2032 | @parent_start_time = @parent_start_time, 2033 | @job_number = @job_number, 2034 | @database_name = @database_name, 2035 | @schema_name = @schema_name, 2036 | @table_name = @table_name, 2037 | @index_name = @index_name, 2038 | @partition_number = @partition_number, 2039 | @alter_start_time = @alter_start_time, 2040 | @first_alter = @first_alter, 2041 | @calculated_do_REBUILD = @calculated_do_REBUILD, 2042 | @calculated_priority = @calculated_priority; 2043 | 2044 | EXEC sp_releaseapplock @Resource = N'UPDATE_CCI_REORG_REBUILD_TABLES'; 2045 | COMMIT TRANSACTION; 2046 | 2047 | IF @calculated_do_REBUILD = 0 2048 | BEGIN 2049 | SET @alter_sql = N'ALTER INDEX ' + QUOTENAME(@index_name) + ' ON ' 2050 | + QUOTENAME(@database_name) + N'.' + QUOTENAME(@schema_name) + N'.' + QUOTENAME(@table_name) + N' REORGANIZE ' 2051 | + CASE WHEN @partition_number <> -1 THEN N'PARTITION = ' + CAST(@partition_number AS NVARCHAR(10)) ELSE N'' END 2052 | + N' WITH (COMPRESS_ALL_ROW_GROUPS = ' + CASE WHEN @reorg_use_COMPRESS_ALL_ROWGROUPS_option = 1 THEN N'ON' ELSE N'OFF' END + N')'; 2053 | END 2054 | ELSE 2055 | BEGIN 2056 | SET @alter_sql = N'ALTER INDEX ' + QUOTENAME(@index_name) + ' ON ' 2057 | + QUOTENAME(@database_name) + N'.' + QUOTENAME(@schema_name) + N'.' + QUOTENAME(@table_name) + N' REBUILD ' 2058 | + CASE WHEN @partition_number <> -1 THEN N'PARTITION = ' + CAST(@partition_number AS NVARCHAR(10)) ELSE N'' END 2059 | + N' WITH (ONLINE = ' + CASE WHEN @rebuild_ONLINE_option = 1 THEN N'ON' ELSE N'OFF' END 2060 | + CASE WHEN @rebuild_MAXDOP IS NOT NULL THEN N', MAXDOP = ' + CAST(@rebuild_MAXDOP AS NVARCHAR(10)) ELSE N'' END 2061 | + N')'; 2062 | END; 2063 | 2064 | SELECT @cpu_time_snapshot = cpu_time 2065 | FROM sys.dm_exec_requests 2066 | WHERE session_id = @@SPID; 2067 | 2068 | SET @error_message = NULL; 2069 | BEGIN TRY 2070 | IF @reorg_execute_twice = 1 AND @calculated_do_REBUILD = 0 2071 | BEGIN 2072 | EXEC sp_executesql @alter_sql; 2073 | EXEC sp_executesql @alter_sql; 2074 | END 2075 | ELSE 2076 | BEGIN 2077 | EXEC sp_executesql @alter_sql; 2078 | END; 2079 | END TRY 2080 | BEGIN CATCH 2081 | SET @error_message = ERROR_MESSAGE(); 2082 | END CATCH; 2083 | 2084 | SELECT @cpu_time_snapshot = cpu_time - @cpu_time_snapshot 2085 | FROM sys.dm_exec_requests 2086 | WHERE session_id = @@SPID; 2087 | 2088 | BEGIN TRANSACTION; 2089 | EXEC sp_getapplock @Resource = N'UPDATE_CCI_REORG_REBUILD_TABLES', @LockMode = 'Exclusive'; 2090 | 2091 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'UPDATE ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Index_History 2092 | SET 2093 | Alter_Complete_Time_UTC = CASE WHEN @error_message IS NULL THEN SYSUTCDATETIME() ELSE NULL END 2094 | , Alter_Stop_Time_UTC = CASE WHEN @error_message IS NOT NULL THEN SYSUTCDATETIME() ELSE NULL END 2095 | , Alter_Attempt_CPU_MS = @cpu_time_snapshot 2096 | , Error_Text = @error_message 2097 | , Did_Complete = CASE WHEN @error_message IS NULL THEN 1 ELSE 0 END 2098 | , Did_Error = CASE WHEN @error_message IS NOT NULL THEN 1 ELSE 0 END 2099 | , Did_Stop = CASE WHEN @error_message IS NOT NULL THEN 1 ELSE 0 END 2100 | WHERE Alter_Start_Time_UTC = @alter_start_time 2101 | AND Job_Number = @job_number 2102 | AND Session_Id = @@SPID'; 2103 | 2104 | EXEC sp_executesql @dynamic_sql_max, 2105 | N'@error_message NVARCHAR(4000), @cpu_time_snapshot INT, @alter_start_time DATETIME2, @job_number SMALLINT', 2106 | @error_message = @error_message, 2107 | @cpu_time_snapshot = @cpu_time_snapshot, 2108 | @alter_start_time = @alter_start_time, 2109 | @job_number = @job_number; 2110 | 2111 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'DELETE FROM ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Partitions_To_Process 2112 | WHERE In_Progress = 1 2113 | AND [Database_Name] = @database_name 2114 | AND [Schema_Name] = @schema_name 2115 | AND Table_Name = @table_name 2116 | AND Index_Name = @index_name 2117 | AND Partition_Number = @partition_number 2118 | AND String_Priority_Helper = @string_priority_helper'; 2119 | 2120 | EXEC sp_executesql @dynamic_sql_max, 2121 | N'@database_name SYSNAME, @schema_name SYSNAME, @table_name SYSNAME, @index_name SYSNAME, @partition_number INT, @string_priority_helper VARCHAR(58)', 2122 | @database_name = @database_name, 2123 | @schema_name = @schema_name, 2124 | @table_name = @table_name, 2125 | @index_name = @index_name, 2126 | @partition_number = @partition_number, 2127 | @string_priority_helper = @string_priority_helper; 2128 | 2129 | EXEC sp_releaseapplock @Resource = N'UPDATE_CCI_REORG_REBUILD_TABLES'; 2130 | COMMIT TRANSACTION; 2131 | 2132 | EXEC [dbo].AgentJobMultiThread_ShouldChildJobHalt 2133 | @workload_identifier = @workload_identifier, 2134 | @logging_database_name = @logging_database_name, 2135 | @logging_schema_name = @logging_schema_name, 2136 | @parent_start_time = @parent_start_time, 2137 | @should_job_halt_OUT = @should_job_stop OUTPUT; 2138 | 2139 | IF @should_job_stop = 1 2140 | BEGIN 2141 | RETURN; 2142 | END; 2143 | END 2144 | ELSE 2145 | BEGIN 2146 | -- table is either empty or it wouldn't be possible to run a REORG on any remaining partition due to SQL Server locks 2147 | -- that is because it is not possible to do REORGs simultaneously on different partitions for the same table 2148 | SET @all_partitions_processed = 1; 2149 | END; 2150 | 2151 | -- @first_alter should be 1 only for the first loop of the procedure 2152 | -- we care about this because we want to know if a previously halted reorg or rebuild had the full maintainence window to run 2153 | SET @first_alter = 0; 2154 | END; 2155 | 2156 | END; 2157 | 2158 | GO 2159 | 2160 | 2161 | 2162 | 2163 | 2164 | 2165 | CREATE OR ALTER PROCEDURE [dbo].[CCI_Reorg_Rebuild_Cleanup_Jobs] ( 2166 | @logging_database_name SYSNAME, 2167 | @logging_schema_name SYSNAME, 2168 | @parent_start_time DATETIME2, 2169 | @max_minutes_to_run SMALLINT 2170 | ) 2171 | AS 2172 | BEGIN 2173 | /* 2174 | Procedure Name: CCI_Reorg_Rebuild_Cleanup_Jobs 2175 | Author: Joe Obbish 2176 | Version: 1.0 2177 | Updates: https://github.com/jobbish-sql/SQL-Server-Multi-Thread 2178 | License: MIT 2179 | Purpose: To be called by the multithreading job framework. You should not be executing this stored procedure yourself. 2180 | */ 2181 | DECLARE @workload_identifier NVARCHAR(50) = N'CCI_Reorg_Rebuild', 2182 | @stop_jobs BIT, 2183 | @custom_procedure_error_message NVARCHAR(4000), 2184 | @cleanup_error_message NVARCHAR(4000), 2185 | @error_count_found_during_this_procedure INT = 0, 2186 | @error_count_from_cleanup INT, 2187 | @end_stored_procedure_name_to_run SYSNAME, 2188 | @dynamic_sql_max NVARCHAR(MAX) = CAST(N'' AS NVARCHAR(MAX)), 2189 | @error_message NVARCHAR(4000), 2190 | @used_job_prefix NVARCHAR(20), 2191 | @nice_error_message NVARCHAR(4000), 2192 | @code_schema_name SYSNAME = OBJECT_SCHEMA_NAME(@@PROCID); 2193 | 2194 | SET NOCOUNT ON; 2195 | 2196 | -- get needed parameter values from the summary table for this run 2197 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'SELECT 2198 | @end_stored_procedure_name_to_run_OUT = End_Stored_Procedure_Name_To_Run 2199 | , @used_job_prefix_OUT = Used_Job_Prefix 2200 | FROM ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Summary 2201 | WHERE Summary_Start_Time_UTC = @parent_start_time'; 2202 | 2203 | EXEC sp_executesql @dynamic_sql_max, 2204 | N'@end_stored_procedure_name_to_run_OUT SYSNAME OUTPUT, @used_job_prefix_OUT NVARCHAR(100) OUTPUT, @parent_start_time DATETIME2', 2205 | @end_stored_procedure_name_to_run_OUT = @end_stored_procedure_name_to_run OUTPUT, 2206 | @used_job_prefix_OUT = @used_job_prefix OUTPUT, 2207 | @parent_start_time = @parent_start_time; 2208 | 2209 | 2210 | -- there was likely a problem with the parent procedure if this is NULL 2211 | IF @used_job_prefix IS NULL 2212 | BEGIN 2213 | THROW 70010, 'Cannot find expected row in CCI_Reorg_Rebuild_Summary table. Look for an error logged by the CCIReorgAndRebuild stored procedure.', 1; 2214 | RETURN; 2215 | END; 2216 | 2217 | 2218 | EXEC [dbo].AgentJobMultiThread_ShouldCleanupStopChildJobs 2219 | @workload_identifier = @workload_identifier, 2220 | @parent_start_time = @parent_start_time, 2221 | @job_prefix = @used_job_prefix, 2222 | @max_minutes_to_run = @max_minutes_to_run, 2223 | @should_stop_jobs_OUT = @stop_jobs OUTPUT; 2224 | 2225 | 2226 | IF @stop_jobs = 0 2227 | BEGIN 2228 | EXEC [dbo].AgentJobMultiThread_FinalizeCleanup 2229 | @workload_identifier = @workload_identifier, 2230 | @job_prefix = @used_job_prefix, 2231 | @retry_cleanup = 1; 2232 | 2233 | RETURN; 2234 | END; 2235 | 2236 | 2237 | -- save off cpu time to try to update the CCI_Reorg_Rebuild_Index_History table for stopped jobs 2238 | CREATE TABLE #cpu_time_by_session_id (session_id INT NOT NULL, cpu_time INT); 2239 | 2240 | INSERT INTO #cpu_time_by_session_id (session_id, cpu_time) 2241 | SELECT r.session_id, r.cpu_time 2242 | FROM sys.dm_exec_requests r 2243 | INNER JOIN sys.dm_exec_sessions s ON r.session_id = s.session_id 2244 | WHERE s.is_user_process = 1 2245 | OPTION (MAXDOP 1); 2246 | 2247 | EXEC [dbo].AgentJobMultiThread_CleanupChildJobs 2248 | @workload_identifier = @workload_identifier, 2249 | @logging_database_name = @logging_database_name, 2250 | @logging_schema_name = @logging_schema_name, 2251 | @job_prefix = @used_job_prefix, 2252 | @child_job_error_count_OUT = @error_count_from_cleanup OUTPUT, 2253 | @cleanup_error_message_OUT = @cleanup_error_message OUTPUT; 2254 | 2255 | 2256 | BEGIN TRANSACTION; 2257 | EXEC sp_getapplock @Resource = N'UPDATE_CCI_REORG_REBUILD_TABLES', @LockMode = 'Exclusive'; 2258 | 2259 | -- make a reasonable effort to update cpu time and other columns for jobs that were likely stopped 2260 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'UPDATE hist 2261 | SET hist.Alter_Stop_Time_UTC = SYSUTCDATETIME() 2262 | , hist.Did_Complete = 0 2263 | , hist.Did_Error = 0 2264 | , hist.Did_Stop = 1 2265 | , hist.Alter_Attempt_CPU_MS = ( 2266 | SELECT ISNULL(MAX(cpu_time), 0) 2267 | FROM #cpu_time_by_session_id s 2268 | WHERE s.session_id = hist.Session_Id 2269 | ) 2270 | - ( 2271 | SELECT ISNULL(SUM(Alter_Attempt_CPU_MS), 0) 2272 | FROM ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Index_History h 2273 | WHERE h.Session_Id = hist.Session_Id 2274 | AND h.Alter_Start_Time_UTC >= @parent_start_time 2275 | AND h.Summary_Start_Time_UTC = @parent_start_time 2276 | ) 2277 | FROM ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Index_History hist 2278 | WHERE hist.Alter_Start_Time_UTC >= @parent_start_time 2279 | AND hist.Summary_Start_Time_UTC = @parent_start_time 2280 | AND hist.Alter_Stop_Time_UTC IS NULL 2281 | AND hist.Alter_Complete_Time_UTC IS NULL'; 2282 | 2283 | EXEC sp_executesql @dynamic_sql_max, 2284 | N'@parent_start_time DATETIME2', 2285 | @parent_start_time = @parent_start_time; 2286 | 2287 | -- purge rows from permanent tables older than 100 days 2288 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'DELETE FROM ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Index_History WITH (TABLOCK) 2289 | WHERE Alter_Start_Time_UTC < DATEADD(DAY, -100, SYSUTCDATETIME())'; 2290 | 2291 | EXEC sp_executesql @dynamic_sql_max; 2292 | 2293 | EXEC sp_releaseapplock @Resource = N'UPDATE_CCI_REORG_REBUILD_TABLES'; 2294 | COMMIT TRANSACTION; 2295 | 2296 | -- purge rows from permanent tables older than 100 days 2297 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'DELETE FROM ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Summary WITH (TABLOCK) 2298 | WHERE Summary_Start_Time_UTC < DATEADD(DAY, -100, SYSUTCDATETIME())'; 2299 | 2300 | EXEC sp_executesql @dynamic_sql_max; 2301 | 2302 | -- run the custom end procedure, if set 2303 | IF @end_stored_procedure_name_to_run IS NOT NULL 2304 | BEGIN 2305 | BEGIN TRY 2306 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + QUOTENAME(@code_schema_name) + N'.' + QUOTENAME(@end_stored_procedure_name_to_run); 2307 | EXEC sp_executesql @dynamic_sql_max; 2308 | END TRY 2309 | BEGIN CATCH 2310 | SET @custom_procedure_error_message = ERROR_MESSAGE(); 2311 | SET @error_count_found_during_this_procedure = @error_count_found_during_this_procedure + 1; 2312 | END CATCH; 2313 | END; 2314 | 2315 | -- add in errors from child jobs 2316 | SET @error_count_found_during_this_procedure = @error_count_found_during_this_procedure + @error_count_from_cleanup; 2317 | 2318 | BEGIN TRANSACTION; 2319 | EXEC sp_getapplock @Resource = N'UPDATE_CCI_REORG_REBUILD_TABLES', @LockMode = 'Exclusive'; 2320 | 2321 | -- update summary table 2322 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'UPDATE ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Summary 2323 | SET Summary_End_Time_UTC = SYSUTCDATETIME() 2324 | , Alter_Statements_Completed = h.Alter_Statements_Completed 2325 | , Alter_Statements_Halted = h.Alter_Statements_Halted 2326 | , Alter_Statements_Not_Started = p.Alter_Statements_Not_Started 2327 | , Alter_Statements_With_Priority_Zero = p.Alter_Statements_With_Priority_Zero 2328 | , Approximate_Error_Count = @error_count_found_during_this_procedure + h.Alter_Statements_Error 2329 | , Alter_Total_CPU_MS = h.Alter_Total_CPU_MS 2330 | , Custom_End_Procedure_Name_Error_Text = @custom_procedure_error_message 2331 | , Cleanup_Error_Text = @cleanup_error_message 2332 | FROM ( 2333 | SELECT 2334 | COUNT_BIG(hist.Alter_Complete_Time_UTC) Alter_Statements_Completed 2335 | , COUNT_BIG(hist.Alter_Stop_Time_UTC) Alter_Statements_Halted 2336 | , COUNT_BIG(hist.Error_Text) Alter_Statements_Error 2337 | , SUM(1.0 * hist.Alter_Attempt_CPU_MS) Alter_Total_CPU_MS 2338 | FROM ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Index_History hist 2339 | WHERE hist.Alter_Start_Time_UTC >= @parent_start_time 2340 | AND hist.Summary_Start_Time_UTC = @parent_start_time 2341 | ) h 2342 | CROSS JOIN 2343 | ( 2344 | SELECT 2345 | SUM(CASE WHEN In_Progress = 0 THEN 1 ELSE 0 END) Alter_Statements_Not_Started 2346 | , SUM(CASE WHEN In_Progress = -1 THEN 1 ELSE 0 END) Alter_Statements_With_Priority_Zero 2347 | FROM ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Partitions_To_Process WITH (FORCESEEK) 2348 | WHERE In_Progress IN (0, -1) 2349 | ) p 2350 | WHERE ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.CCI_Reorg_Rebuild_Summary.Summary_Start_Time_UTC = @parent_start_time'; 2351 | 2352 | EXEC sp_executesql @dynamic_sql_max, 2353 | N'@error_count_found_during_this_procedure INT, @custom_procedure_error_message NVARCHAR(4000), @cleanup_error_message NVARCHAR(4000), @parent_start_time DATETIME2', 2354 | @error_count_found_during_this_procedure = @error_count_found_during_this_procedure, 2355 | @custom_procedure_error_message = @custom_procedure_error_message, 2356 | @cleanup_error_message = @cleanup_error_message, 2357 | @parent_start_time = @parent_start_time; 2358 | 2359 | EXEC sp_releaseapplock @Resource = N'UPDATE_CCI_REORG_REBUILD_TABLES'; 2360 | COMMIT TRANSACTION; 2361 | 2362 | 2363 | EXEC [dbo].AgentJobMultiThread_FinalizeCleanup 2364 | @workload_identifier = @workload_identifier, 2365 | @job_prefix = @used_job_prefix, 2366 | @retry_cleanup = 0; 2367 | 2368 | END; 2369 | 2370 | GO 2371 | -------------------------------------------------------------------------------- /cci_maintenance/CCI_Reorg_Rebuild_Tables.sql: -------------------------------------------------------------------------------- 1 | -- feel free to change the schema as long as it is consistent 2 | CREATE TABLE dbo.CCI_Reorg_Rebuild_Summary ( 3 | Summary_Start_Time_UTC DATETIME2 NOT NULL, 4 | Summary_End_Time_UTC DATETIME2 NULL, 5 | Alter_Statements_Completed INT NULL, 6 | Alter_Statements_Halted INT NULL, 7 | Alter_Statements_Not_Started INT NULL, 8 | Alter_Statements_With_Priority_Zero INT NULL, 9 | Alter_Total_CPU_MS BIGINT NULL, 10 | Approximate_Error_Count INT NULL, 11 | Custom_Start_Procedure_Name_Error_Text NVARCHAR(4000) NULL, 12 | Custom_End_Procedure_Name_Error_Text NVARCHAR(4000) NULL, 13 | Cleanup_Error_Text NVARCHAR(4000) NULL, 14 | CCI_Included_Database_Name_List NVARCHAR(4000) NOT NULL, 15 | CCI_Excluded_Schema_Name_List NVARCHAR(4000) NULL, 16 | CCI_Excluded_Table_Name_List NVARCHAR(4000) NULL, 17 | Max_CCI_Alter_Job_Count SMALLINT NULL, 18 | Max_Minutes_To_Run SMALLINT NOT NULL, 19 | Partition_Priority_Algorithm_Name NVARCHAR(100), 20 | Used_SQL_Expression_For_Partition_Priority_Calculation NVARCHAR(4000) NULL, 21 | Rebuild_Algorithm_Name NVARCHAR(100), 22 | Used_SQL_Expression_For_Rebuild_Calculation NVARCHAR(4000) NULL, 23 | Ignore_Archive_Compressed_Partitions BIT NOT NULL, 24 | Reorg_Use_COMPRESS_ALL_ROWGROUPS_Option BIT NOT NULL, 25 | Reorg_Execute_Twice BIT NOT NULL, 26 | Rebuild_MAXDOP SMALLINT NULL, 27 | Rebuild_ONLINE_Option BIT NOT NULL, 28 | Start_Stored_Procedure_Name_To_Run SYSNAME NULL, 29 | End_Stored_Procedure_Name_To_Run SYSNAME NULL, 30 | Disable_CPU_Rescheduling BIT NULL, 31 | Delimiter_Override NVARCHAR(1) NULL, 32 | Used_Job_Prefix NVARCHAR(100) NOT NULL, 33 | Prioritization_Only BIT NULL, 34 | query_CCI_DMV_info BIT NOT NULL 35 | ); 36 | 37 | CREATE CLUSTERED INDEX CI_CCI_Reorg_Rebuild_Summary ON dbo.CCI_Reorg_Rebuild_Summary (Summary_Start_Time_UTC); 38 | 39 | CREATE TABLE dbo.CCI_Reorg_Rebuild_Index_History ( 40 | Summary_Start_Time_UTC DATETIME2 NOT NULL, 41 | Job_Number SMALLINT NOT NULL, 42 | Database_Name SYSNAME NOT NULL, 43 | [Schema_Name] SYSNAME NOT NULL, 44 | Table_Name SYSNAME NOT NULL, 45 | Index_Name SYSNAME NOT NULL, 46 | Partition_Number INT NOT NULL, 47 | Was_Rebuild INT NOT NULL, 48 | Alter_Start_Time_UTC DATETIME2 NOT NULL, 49 | Alter_Stop_Time_UTC DATETIME2 NULL, 50 | Alter_Complete_Time_UTC DATETIME2 NULL, 51 | Session_Id INT NOT NULL, 52 | Was_First_Alter_Of_Run BIT NOT NULL, 53 | Did_Complete BIT NULL, 54 | Did_Error BIT NULL, 55 | Did_Stop BIT NULL, 56 | Calculated_Priority NUMERIC(38, 0) NULL, 57 | Alter_Attempt_CPU_MS INT NULL, 58 | Error_Text NVARCHAR(4000) NULL 59 | ); 60 | 61 | CREATE CLUSTERED INDEX CI_CCI_Reorg_Rebuild_Index_History ON dbo.CCI_Reorg_Rebuild_Index_History (Alter_Start_Time_UTC, Job_Number); 62 | 63 | CREATE NONCLUSTERED INDEX NCI_CCI_Reorg_Rebuild_Index_History ON dbo.CCI_Reorg_Rebuild_Index_History ( 64 | Was_First_Alter_Of_Run, 65 | Did_Complete, 66 | Did_Error, 67 | Did_Stop, 68 | [Database_Name], 69 | [Schema_Name], 70 | Table_Name, 71 | Index_Name, 72 | Partition_Number, 73 | Alter_Start_Time_UTC 74 | ) INCLUDE (Was_Rebuild); 75 | -------------------------------------------------------------------------------- /core/sp_AgentJobMultiThread.sql: -------------------------------------------------------------------------------- 1 | SET ANSI_NULLS ON; 2 | SET ANSI_PADDING ON; 3 | SET ANSI_WARNINGS ON; 4 | SET ARITHABORT ON; 5 | SET CONCAT_NULL_YIELDS_NULL ON; 6 | SET QUOTED_IDENTIFIER ON; 7 | GO 8 | 9 | CREATE OR ALTER PROCEDURE [dbo].AgentJobMultiThread_Help 10 | AS 11 | BEGIN 12 | /* 13 | Procedure Name: AgentJobMultiThread_Help 14 | Author: Joe Obbish 15 | Version: 1.0 16 | Updates: https://github.com/jobbish-sql/SQL-Server-Multi-Thread 17 | License: MIT 18 | Purpose: 19 | 20 | Call this procedure to get T-SQL result sets that explain how to use the AgentJobMultiThread framework. 21 | */ 22 | 23 | SELECT v.txt AS [Main Features] 24 | FROM ( 25 | VALUES 26 | (N'Create multiple threads to do work concurrently'), 27 | (N'Stops all work at specified time limit'), 28 | (N'Attempts to balance work among SQL Server schedulers') 29 | ) v (txt); 30 | 31 | 32 | SELECT v.txt AS [Requirements] 33 | FROM ( 34 | VALUES 35 | (N'SQL Server 2019, SQL Server 2017, or SQL Server 2016 SP2+'), 36 | (N'Standard, Developer, or Enterprise editions'), 37 | (N'Ability to create and run T-SQL Agent Jobs'), 38 | (N'VIEW_SERVER_STATE permission for the caller'), 39 | (N'SQLAgentUserRole or similar database role for the caller'), 40 | (N'db_datareader on the msdb database for the caller'), 41 | (N'execute procedure on this database for the caller'), 42 | (N'db_ddladmin, db_datawriter, db_datareader on the logging schema (@logging_schema_name) in the logging database (@logging_database_name) for the caller') 43 | ) v (txt); 44 | 45 | 46 | SELECT v.txt AS [Creating a workload parent procedure] 47 | FROM ( 48 | VALUES 49 | (N'A parent procedure serves as the application entry point for the AgentJobMultiThread framework.'), 50 | (N'Reference the ThreadingDemoParent procedure in the demo folder for a simple example.'), 51 | (N'There are no required parameters.'), 52 | (N'Example code flow:'), 53 | (N' STEP 1: Run standard validation by calling AgentJobMultiThread_InitialValidation and quit if there are reported issues'), 54 | (N' STEP 2: Run additional validation specific to to your workload and quit if there are reported issues'), 55 | (N' STEP 3: Do setup work specific to your workload including creating and populated needed tables'), 56 | (N' STEP 4: Create the agent jobs by calling AgentJobMultiThread_CreateAgentJobs') 57 | ) v (txt); 58 | 59 | 60 | SELECT v.txt AS [Creating a workload child procedure] 61 | FROM ( 62 | VALUES 63 | (N'A child procedure serves as the application multithreading area for the AgentJobMultiThread framework.'), 64 | (N'Reference the ThreadingDemoChild procedure in the demo folder for a simple example.'), 65 | (N'Parameters must exactly match the following:'), 66 | (N' @logging_database_name SYSNAME,'), 67 | (N' @logging_schema_name SYSNAME,)'), 68 | (N' @parent_start_time DATETIME2,'), 69 | (N' @job_number SMALLINT,'), 70 | (N' @job_attempt_number SMALLINT'), 71 | (N'Example code flow:'), 72 | (N' STEP 1: Do any prep work such as getting additional parameters from a summary table'), 73 | (N' STEP 2: Call AgentJobMultiThread_RescheduleChildJobIfNeeded and quit if the child procedure will be rescheduled'), 74 | (N' STEP 3: In a loop, find the next unit of work'), 75 | (N' STEP 4: In a loop, complete the unit of work'), 76 | (N' STEP 5: In a loop, call AgentJobMultiThread_ShouldChildJobHalt and quit if needed') 77 | ) v (txt); 78 | 79 | 80 | SELECT v.txt AS [Creating a workload cleanup procedure] 81 | FROM ( 82 | VALUES 83 | (N'A cleanup procedure serves as the application end point for the AgentJobMultiThread framework.'), 84 | (N'Reference the ThreadingDemoCleanup procedure in the demo folder for a simple example.'), 85 | (N'Parameters must exactly match the following:'), 86 | (N' @logging_database_name SYSNAME,'), 87 | (N' @logging_schema_name SYSNAME,)'), 88 | (N' @parent_start_time DATETIME2,'), 89 | (N' @max_minutes_to_run SMALLINT'), 90 | (N'Example code flow:'), 91 | (N' STEP 1: Do any prep work such as getting additional parameters from a summary table'), 92 | (N' STEP 2: Call AgentJobMultiThread_ShouldCleanupStopChildJobs to determine if cleanup should occur'), 93 | (N' STEP 3: If cleanup should not occur yet then call AgentJobMultiThread_FinalizeCleanup and quit'), 94 | (N' STEP 4: If cleanup should occur then call AgentJobMultiThread_CleanupChildJobs'), 95 | (N' STEP 5: Complete any other necessary work in the procedure such as updating summary tables'), 96 | (N' STEP 6: Call AgentJobMultiThread_FinalizeCleanup to clean up agent jobs and schedules') 97 | ) v (txt); 98 | 99 | RETURN; 100 | END; 101 | 102 | GO 103 | 104 | 105 | 106 | 107 | 108 | 109 | 110 | CREATE OR ALTER PROCEDURE [dbo].AgentJobMultiThread_Internal_ValidateCommonParameters ( 111 | @workload_identifier NVARCHAR(50), 112 | @logging_database_name SYSNAME, 113 | @logging_schema_name SYSNAME, 114 | @parent_start_time DATETIME2, 115 | @is_valid_OUT BIT OUTPUT, 116 | @error_message_OUT NVARCHAR(4000) OUTPUT 117 | ) 118 | AS 119 | BEGIN 120 | /* 121 | Procedure Name: AgentJobMultiThread_Internal_ValidateCommonParameters 122 | Author: Joe Obbish 123 | Version: 1.0 124 | Updates: https://github.com/jobbish-sql/SQL-Server-Multi-Thread 125 | License: MIT 126 | Purpose: 127 | 128 | An internal procedure used to check common issues with parameters. 129 | You should not directly call this procedure. 130 | 131 | 132 | Parameter help: 133 | 134 | @workload_identifier NVARCHAR(50): 135 | 136 | An identifier to use for the workload. This identifier will be added to any agent jobs and tables 137 | that are created by the framework. Use a consistent value for this identifier for the parent, child, and cleanup procedures. 138 | 139 | 140 | @logging_database_name SYSNAME: 141 | 142 | Use this parameter if you want tables to be created in a different database than the database that 143 | contains the AgentJobMultiThread stored procedures. 144 | The default value is to use the database context of the AgentJobMultiThread stored procedures. 145 | 146 | 147 | @logging_schema_name SYSNAME: 148 | 149 | Use this parameter if you want tables to be created in a different schema than the schema that 150 | contains the AgentJobMultiThread stored procedures. 151 | The default value is to use the schema context of the AgentJobMultiThread stored procedures. 152 | 153 | 154 | @parent_start_time DATETIME2: 155 | 156 | The start time of the workload, preferably expressed in UTC. 157 | Use a consistent value for this value for each iteration of the workload for the parent, child, and cleanup procedures. 158 | 159 | 160 | @is_valid_OUT BIT OUTPUT: 161 | 162 | Works with the @error_message_OUT @parameter. 163 | An output parameter used to report validation issues. If set to 1 then there is a problem that must be addressed. 164 | The caller should halt and the value for the output parameter @error_message_OUT should be returned to the client in some way. 165 | 166 | 167 | @error_message_OUT NVARCHAR(4000) OUTPUT: 168 | 169 | Works with the is_valid_OUT @parameter. 170 | An output parameter used to report validation issues. If not null then there is a problem that must be addressed. 171 | The caller should halt and the value for the output parameter @error_message_OUT should be returned to the client in some way. 172 | */ 173 | 174 | DECLARE @dynamic_sql_max NVARCHAR(MAX) = CAST(N'' AS NVARCHAR(MAX)), 175 | @dynamic_sql_result_set_exists BIT; 176 | 177 | SET NOCOUNT ON; 178 | 179 | SET @is_valid_OUT = 0; 180 | 181 | 182 | -- check @workload_identifier 183 | IF @workload_identifier IS NULL 184 | BEGIN 185 | SET @error_message_OUT = N'The @workload_identifier parameter must not be NULL.'; 186 | RETURN; 187 | END; 188 | 189 | 190 | -- can't only pass in schema name 191 | IF @logging_schema_name IS NOT NULL AND @logging_database_name IS NULL 192 | BEGIN 193 | SET @error_message_OUT = N'If @logging_schema_name is not NULL then @logging_database_name must also not be NULL.'; 194 | RETURN; 195 | END; 196 | 197 | 198 | -- check if logging database exists 199 | IF @logging_database_name IS NOT NULL AND NOT EXISTS ( 200 | SELECT 1 201 | FROM sys.databases 202 | WHERE name = @logging_database_name 203 | ) 204 | BEGIN 205 | SET @error_message_OUT = QUOTENAME(@logging_database_name) + N' was entered as the @logging_database_name parameter but it does not exist as a database.'; 206 | RETURN; 207 | END; 208 | 209 | 210 | IF @logging_schema_name IS NOT NULL 211 | BEGIN 212 | -- validate logging schema exists 213 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'SELECT @dynamic_sql_result_set_exists_OUT = 1 214 | FROM ' + QUOTENAME(@logging_database_name) + N'.sys.schemas 215 | WHERE name = @logging_schema_name'; 216 | 217 | SET @dynamic_sql_result_set_exists = 0; 218 | EXEC sp_executesql @dynamic_sql_max, 219 | N'@logging_schema_name SYSNAME, @dynamic_sql_result_set_exists_OUT BIT OUTPUT', 220 | @logging_schema_name = @logging_schema_name, 221 | @dynamic_sql_result_set_exists_OUT = @dynamic_sql_result_set_exists OUTPUT; 222 | 223 | IF @dynamic_sql_result_set_exists = 0 224 | BEGIN 225 | SET @error_message_OUT = N'Cannot find ' + QUOTENAME(@logging_schema_name) + N' schema in the ' + QUOTENAME(@logging_database_name) + N' database.'; 226 | RETURN; 227 | END; 228 | END; 229 | 230 | 231 | -- check @parent_start_time 232 | IF @parent_start_time IS NULL 233 | BEGIN 234 | SET @error_message_OUT = N'The @parent_start_time parameter must not be NULL.'; 235 | RETURN; 236 | END; 237 | 238 | -- all checks passed 239 | SET @is_valid_OUT = 1; 240 | 241 | RETURN; 242 | END; 243 | 244 | GO 245 | 246 | 247 | 248 | 249 | 250 | 251 | 252 | 253 | CREATE OR ALTER PROCEDURE [dbo].AgentJobMultiThread_Internal_CheckProcedureExists ( 254 | @procedure_name SYSNAME, 255 | @procedure_exists_OUT BIT OUTPUT 256 | ) 257 | AS 258 | BEGIN 259 | /* 260 | Procedure Name: AgentJobMultiThread_Internal_CheckProcedureExists 261 | Author: Joe Obbish 262 | Version: 1.0 263 | Updates: https://github.com/jobbish-sql/SQL-Server-Multi-Thread 264 | License: MIT 265 | Purpose: 266 | 267 | An internal procedure used to check if a stored procedure exists. 268 | You should not directly call this procedure. 269 | 270 | 271 | Parameter help: 272 | 273 | @procedure_name SYSNAME: 274 | 275 | The name of the stored procedure to check existence for. 276 | This stored procedure must exist in the same database and schema as the AgentJobMultiThread. 277 | 278 | 279 | @procedure_exists_OUT BIT OUTPUT: 280 | 281 | An output parameter that reports if the stored procedure @procedure_name exists in the database and schema. 282 | Set to 1 if the procedure exists and set to 0 if the procedure does not exist. 283 | */ 284 | 285 | DECLARE @dynamic_sql_max NVARCHAR(MAX) = CAST(N'' AS NVARCHAR(MAX)), 286 | @procedure_exists BIT, 287 | @code_database_name SYSNAME = DB_NAME(), -- all code objects are required to exist on the same database and schema 288 | @code_schema_name SYSNAME = OBJECT_SCHEMA_NAME(@@PROCID); 289 | 290 | 291 | SET NOCOUNT ON; 292 | 293 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'SELECT @procedure_exists_dynamic_OUT = 1 294 | FROM ' + QUOTENAME(@code_database_name) + N'.sys.objects o 295 | INNER JOIN ' + QUOTENAME(@code_database_name) + N'.sys.schemas s ON o.[schema_id] = s.[schema_id] 296 | where o.name = @procedure_name 297 | AND s.name = @code_schema_name 298 | AND o.type = ''P'''; 299 | 300 | SET @procedure_exists_OUT = 0; 301 | EXEC sp_executesql @dynamic_sql_max, 302 | N'@procedure_name SYSNAME, @code_schema_name SYSNAME, @procedure_exists_dynamic_OUT BIT OUTPUT', 303 | @procedure_name = @procedure_name, 304 | @code_schema_name = @code_schema_name, 305 | @procedure_exists_dynamic_OUT = @procedure_exists_OUT OUTPUT; 306 | 307 | 308 | RETURN; 309 | END; 310 | 311 | GO 312 | 313 | 314 | 315 | 316 | 317 | 318 | 319 | CREATE OR ALTER PROCEDURE [dbo].AgentJobMultiThread_InitialValidation ( 320 | @workload_identifier NVARCHAR(50), 321 | @logging_database_name SYSNAME = NULL, 322 | @logging_schema_name SYSNAME = NULL, 323 | @parent_start_time DATETIME2, 324 | @child_stored_procedure_name SYSNAME, 325 | @cleanup_stored_procedure_name SYSNAME, 326 | @max_minutes_to_run SMALLINT, 327 | @total_jobs_to_create SMALLINT, 328 | @is_valid_OUT BIT OUTPUT, 329 | @error_message_OUT NVARCHAR(4000) OUTPUT 330 | ) 331 | AS 332 | BEGIN 333 | /* 334 | Procedure Name: AgentJobMultiThread_InitialValidation 335 | Author: Joe Obbish 336 | Version: 1.0 337 | Updates: https://github.com/jobbish-sql/SQL-Server-Multi-Thread 338 | License: MIT 339 | Purpose: 340 | 341 | This stored procedure should be called by the application workload parent procedure to verify permissions, 342 | that T-SQL agent jobs can be created, and to check for other common validation issues. 343 | Note that it is not possible to check for every issue. 344 | For example, a login might be sysadmin but still not be able to create T-SQL Agent jobs. 345 | 346 | It is important to check the value of the @is_valid_OUT and the @error_message_OUT parameters. 347 | 348 | 349 | Parameter help: 350 | 351 | @workload_identifier NVARCHAR(50): 352 | 353 | An identifier to use for the workload. This identifier will be added to any agent jobs and tables 354 | that are created by the framework. Use a consistent value for this identifier for the parent, child, and cleanup procedures. 355 | 356 | 357 | @logging_database_name SYSNAME: 358 | 359 | Use this parameter if you want tables to be created in a different database than the database that 360 | contains the AgentJobMultiThread stored procedures. 361 | The default value is to use the database context of the AgentJobMultiThread stored procedures. 362 | 363 | 364 | @logging_schema_name SYSNAME: 365 | 366 | Use this parameter if you want tables to be created in a different schema than the schema that 367 | contains the AgentJobMultiThread stored procedures. 368 | The default value is to use the schema context of the AgentJobMultiThread stored procedures. 369 | 370 | 371 | @parent_start_time DATETIME2: 372 | 373 | The start time of the workload, preferably expressed in UTC. 374 | Use a consistent value for this value for each iteration of the workload for the parent, child, and cleanup procedures. 375 | 376 | 377 | @child_stored_procedure_name SYSNAME: 378 | 379 | The name of the stored procedure used to perform the "child" work for the workload. 380 | This stored procedure must exist in the same database and schema as the AgentJobMultiThread. 381 | Reference AgentJobMultiThread_Help if you need more information. 382 | 383 | 384 | @cleanup_stored_procedure_name SYSNAME: 385 | 386 | The name of the stored procedure used to perform the "cleanup" work for the workload. 387 | This stored procedure must exist in the same database and schema as the AgentJobMultiThread. 388 | Reference AgentJobMultiThread_Help if you need more information. 389 | 390 | 391 | @max_minutes_to_run SMALLINT: 392 | 393 | The maximum number of minutes the workload is allowed to run before all child jobs are stopped. 394 | 395 | 396 | @total_jobs_to_create SMALLINT: 397 | 398 | The number of "child" jobs that will be created. Use this to set maximum concurrency of the workload. 399 | This is a required parameter with no default value. Going above the CPU count of the server is not recommended. 400 | 401 | 402 | @is_valid_OUT BIT OUTPUT: 403 | 404 | Works with the @error_message_OUT @parameter. 405 | An output parameter used to report validation issues. If set to 1 then there is a problem that must be addressed. 406 | The caller should halt and the value for the output parameter @error_message_OUT should be returned to the client in some way. 407 | 408 | 409 | @error_message_OUT NVARCHAR(4000) OUTPUT: 410 | 411 | Works with the is_valid_OUT @parameter. 412 | An output parameter used to report validation issues. If not null then there is a problem that must be addressed. 413 | The caller should halt and the value for the output parameter @error_message_OUT should be returned to the client in some way. 414 | */ 415 | 416 | DECLARE @product_version INT, 417 | @dynamic_sql_max NVARCHAR(MAX), 418 | @dynamic_sql_result_set_exists BIT, 419 | @procedure_exists BIT, 420 | @is_valid_common BIT, 421 | @permission_check BIT, 422 | @error_message_common NVARCHAR(4000), 423 | @code_schema_name SYSNAME = OBJECT_SCHEMA_NAME(@@PROCID); 424 | 425 | SET NOCOUNT ON; 426 | 427 | 428 | SET @is_valid_OUT = 0; 429 | 430 | 431 | -- check for outer transaction or for implicit transactions 432 | IF @@TRANCOUNT > 0 433 | BEGIN 434 | SET @error_message_OUT = N'Cannot be called in an outer transaction because agent jobs may not start as expected.'; 435 | RETURN; 436 | END; 437 | 438 | 439 | -- not able to test on other engines 440 | IF SERVERPROPERTY('EngineEdition') NOT IN (2, 3, 8) 441 | BEGIN 442 | SET @error_message_OUT = N'Only supported for Managed Instances and on-premises versions of SQL Server.'; 443 | RETURN; 444 | END; 445 | 446 | 447 | -- fail if on older version than 2016 SP2 448 | -- it would likely be straightforward to make the agent framework work on SQL Server 2012 and 2014 but this has not been tested 449 | SET @product_version = TRY_CAST(PARSENAME(CONVERT(NVARCHAR(20),SERVERPROPERTY('ProductVersion')), 4) AS INT); 450 | IF SERVERPROPERTY('EngineEdition') <> 8 AND (@product_version < 13 OR (@product_version = 13 AND TRY_CAST(PARSENAME(CONVERT(NVARCHAR(20),SERVERPROPERTY('ProductVersion')), 2) AS INT) < 5026)) 451 | BEGIN 452 | SET @error_message_OUT = N'Not tested on versions older than SQL Server 2016. Comment out this check in AgentJobMultiThread_InitialValidation at your own risk to run on older versions.'; 453 | RETURN; 454 | END; 455 | 456 | 457 | -- need the ability to run agent jobs so limit support to Managed Instances, standard, developer, and enterprise 458 | IF SERVERPROPERTY('EditionID') NOT IN (1804890536, 1872460670, 610778273, -2117995310, -1534726760, 1674378470) 459 | BEGIN 460 | SET @error_message_OUT = N'Only supported on SQL Server Managed Instances, Enterprise, Developer, and Standard editions.'; 461 | RETURN; 462 | END; 463 | 464 | 465 | -- VIEW_SERVER_STATE permission is required 466 | IF HAS_PERMS_BY_NAME(NULL, NULL, N'VIEW SERVER STATE') = 0 467 | BEGIN 468 | SET @error_message_OUT = N'VIEW_SERVER_STATE permission is required.'; 469 | RETURN; 470 | END; 471 | 472 | 473 | -- SELECT permission on msdb database is required 474 | IF HAS_PERMS_BY_NAME('msdb', N'DATABASE', N'SELECT') = 0 475 | BEGIN 476 | SET @error_message_OUT = N'SELECT permission on msdb database is required.'; 477 | RETURN; 478 | END; 479 | 480 | 481 | -- check if user can start agent jobs 482 | -- docs say sysadmin or in the database roles SQLAgentUserRole, SQLAgentReaderRole, SQLAgentOperatorRole 483 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'SELECT @permission_check_OUT = 1 484 | FROM ( 485 | VALUES 486 | (IS_SRVROLEMEMBER(''sysadmin'')), 487 | (IS_ROLEMEMBER(''SQLAgentUserRole'')), 488 | (IS_ROLEMEMBER(''SQLAgentReaderRole'')), 489 | (IS_ROLEMEMBER(''SQLAgentOperatorRole'')) 490 | ) v (perm) 491 | HAVING SUM(v.perm) > 0'; 492 | 493 | SET @permission_check = 0; 494 | -- must run in msdb context 495 | EXEC msdb.sys.sp_executesql @dynamic_sql_max, 496 | N'@permission_check_OUT BIT OUTPUT', 497 | @permission_check_OUT = @permission_check OUTPUT; 498 | 499 | IF @permission_check = 0 500 | BEGIN 501 | SET @error_message_OUT = N'User cannot start T-SQL agent jobs due to lack of permissions.'; 502 | RETURN; 503 | END; 504 | 505 | 506 | -- check if agent job service is running 507 | IF EXISTS ( 508 | SELECT 1 509 | FROM sys.dm_server_services dss 510 | WHERE dss.[servicename] LIKE N'SQL Server Agent (%' 511 | AND dss.[status] IS NULL OR dss.[status] <> 4 512 | ) 513 | BEGIN 514 | SET @error_message_OUT = N'Agent job service is not running.'; 515 | RETURN; 516 | END; 517 | 518 | 519 | -- use stored procedure schema name and database if optional logging parameters aren't set 520 | SET @logging_database_name = ISNULL(@logging_database_name, DB_NAME()); 521 | SET @logging_schema_name = ISNULL(@logging_schema_name, OBJECT_SCHEMA_NAME(@@PROCID)); 522 | 523 | 524 | -- check EXECUTE on code schema 525 | IF HAS_PERMS_BY_NAME(@code_schema_name, N'SCHEMA', N'EXECUTE') = 0 526 | BEGIN 527 | SET @error_message_OUT = N'Executing user must have EXECUTE on the ' + QUOTENAME(@code_schema_name) + N' schema.'; 528 | RETURN; 529 | END; 530 | 531 | 532 | -- check common parameters 533 | EXEC [dbo].AgentJobMultiThread_Internal_ValidateCommonParameters 534 | @workload_identifier = @workload_identifier, 535 | @logging_database_name = @logging_database_name, 536 | @logging_schema_name = @logging_schema_name, 537 | @parent_start_time = @parent_start_time, 538 | @is_valid_OUT = @is_valid_common OUTPUT, 539 | @error_message_OUT = @error_message_common OUTPUT; 540 | 541 | IF @is_valid_common = 0 542 | BEGIN 543 | SET @error_message_OUT = @error_message_common; 544 | RETURN; 545 | END; 546 | 547 | 548 | -- must have SELECT, INSERT, UPDATE, DELETE, and ALTER on the logging schema in the logging database 549 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'USE ' + QUOTENAME(@logging_database_name) + '; 550 | SELECT @dynamic_sql_result_set_exists_OUT = 1 551 | FROM ( 552 | VALUES 553 | (HAS_PERMS_BY_NAME(''' + QUOTENAME(@logging_schema_name) + ''', N''SCHEMA'', N''SELECT'')), 554 | (HAS_PERMS_BY_NAME(''' + QUOTENAME(@logging_schema_name) + ''', N''SCHEMA'', N''INSERT'')), 555 | (HAS_PERMS_BY_NAME(''' + QUOTENAME(@logging_schema_name) + ''', N''SCHEMA'', N''UPDATE'')), 556 | (HAS_PERMS_BY_NAME(''' + QUOTENAME(@logging_schema_name) + ''', N''SCHEMA'', N''DELETE'')), 557 | (HAS_PERMS_BY_NAME(''' + QUOTENAME(@logging_schema_name) + ''', N''SCHEMA'', N''ALTER'')) 558 | ) v (perm) 559 | HAVING SUM(v.perm) = 5'; 560 | 561 | SET @dynamic_sql_result_set_exists = 0; 562 | EXEC sys.sp_executesql @dynamic_sql_max, 563 | N'@dynamic_sql_result_set_exists_OUT BIT OUTPUT', 564 | @dynamic_sql_result_set_exists_OUT = @dynamic_sql_result_set_exists OUTPUT; 565 | 566 | IF @dynamic_sql_result_set_exists = 0 567 | BEGIN 568 | SET @error_message_OUT = N'Executing user must have SELECT, INSERT, UPDATE, DELETE, and ALTER for the ' 569 | + QUOTENAME(@logging_schema_name) + N' schema in the ' + QUOTENAME(@logging_database_name) + N' database.'; 570 | RETURN; 571 | END; 572 | 573 | 574 | -- validate @child_stored_procedure_name 575 | EXEC [dbo].AgentJobMultiThread_Internal_CheckProcedureExists 576 | @procedure_name = @child_stored_procedure_name, 577 | @procedure_exists_OUT = @procedure_exists OUTPUT; 578 | 579 | IF @procedure_exists = 0 580 | BEGIN 581 | SET @error_message_OUT = N'Value for @child_stored_procedure_name does not exist as a stored procedure in the expected database and schema.'; 582 | RETURN; 583 | END; 584 | 585 | 586 | -- validate @cleanup_stored_procedure_name 587 | EXEC [dbo].AgentJobMultiThread_Internal_CheckProcedureExists 588 | @procedure_name = @cleanup_stored_procedure_name, 589 | @procedure_exists_OUT = @procedure_exists OUTPUT; 590 | 591 | IF @procedure_exists = 0 592 | BEGIN 593 | SET @error_message_OUT = N'Value for @cleanup_stored_procedure_name does not exist as a stored procedure in the expected database and schema.'; 594 | RETURN; 595 | END; 596 | 597 | 598 | IF @max_minutes_to_run IS NULL OR @max_minutes_to_run <= 0 599 | BEGIN 600 | SET @error_message_OUT = N'The @max_minutes_to_run parameter must be a positive number.'; 601 | RETURN; 602 | END; 603 | 604 | 605 | IF @total_jobs_to_create IS NULL OR @total_jobs_to_create <= 0 606 | BEGIN 607 | SET @error_message_OUT = N'The @total_jobs_to_create parameter must be a positive number.'; 608 | RETURN; 609 | END; 610 | 611 | 612 | -- all checks passed 613 | SET @is_valid_OUT = 1; 614 | 615 | RETURN; 616 | END; 617 | 618 | GO 619 | 620 | 621 | 622 | 623 | 624 | 625 | 626 | CREATE OR ALTER PROCEDURE [dbo].AgentJobMultiThread_CreateAgentJobs ( 627 | @workload_identifier NVARCHAR(50), 628 | @logging_database_name SYSNAME = NULL, 629 | @logging_schema_name SYSNAME = NULL, 630 | @parent_start_time DATETIME2, 631 | @child_stored_procedure_name SYSNAME, 632 | @cleanup_stored_procedure_name SYSNAME, 633 | @max_minutes_to_run SMALLINT, 634 | @job_prefix NVARCHAR(20) = NULL, 635 | @total_jobs_to_create SMALLINT 636 | ) 637 | AS 638 | BEGIN 639 | /* 640 | Procedure Name: AgentJobMultiThread_CreateAgentJobs 641 | Author: Joe Obbish 642 | Version: 1.0 643 | Updates: https://github.com/jobbish-sql/SQL-Server-Multi-Thread 644 | License: MIT 645 | Purpose: 646 | 647 | This stored procedure should be called by the application workload parent procedure to create the T-SQL agent jobs that call the child procedure. 648 | The owner of the agent jobs will be the executing user. 649 | 650 | The @child_stored_procedure_name stored procedure must exist in the same database and schema as this one and must have the following parameters: 651 | @logging_database_name SYSNAME, 652 | @logging_schema_name SYSNAME, 653 | @parent_start_time DATETIME2, 654 | @job_number SMALLINT, 655 | @job_attempt_number SMALLINT 656 | 657 | The @cleanup_stored_procedure_name stored procedure must exist in the same database and schema as this one and must have the following parameters: 658 | @logging_database_name SYSNAME, 659 | @logging_schema_name SYSNAME, 660 | @parent_start_time DATETIME2, 661 | @max_minutes_to_run SMALLINT' 662 | 663 | For more information about child and cleanup procedures execute the AgentJobMultiThread_Help stored procedure. 664 | 665 | 666 | Parameter help: 667 | 668 | @workload_identifier NVARCHAR(50): 669 | 670 | An identifier to use for the workload. This identifier will be added to any agent jobs and tables 671 | that are created by the framework. Use a consistent value for this identifier for the parent, child, and cleanup procedures. 672 | 673 | 674 | @logging_database_name SYSNAME: 675 | 676 | Use this parameter if you want tables to be created in a different database than the database that 677 | contains the AgentJobMultiThread stored procedures. 678 | The default value is to use the database context of the AgentJobMultiThread stored procedures. 679 | 680 | 681 | @logging_schema_name SYSNAME: 682 | 683 | Use this parameter if you want tables to be created in a different schema than the schema that 684 | contains the AgentJobMultiThread stored procedures. 685 | The default value is to use the schema context of the AgentJobMultiThread stored procedures. 686 | 687 | 688 | @parent_start_time DATETIME2: 689 | 690 | The start time of the workload, preferably expressed in UTC. 691 | Use a consistent value for this value for each iteration of the workload for the parent, child, and cleanup procedures. 692 | 693 | 694 | @child_stored_procedure_name SYSNAME: 695 | 696 | The name of the stored procedure used to perform the "child" work for the workload. 697 | This stored procedure must exist in the same database and schema as the AgentJobMultiThread. 698 | Reference AgentJobMultiThread_Help if you need more information. 699 | 700 | 701 | @cleanup_stored_procedure_name SYSNAME: 702 | 703 | The name of the stored procedure used to perform the "cleanup" work for the workload. 704 | This stored procedure must exist in the same database and schema as the AgentJobMultiThread. 705 | Reference AgentJobMultiThread_Help if you need more information. 706 | 707 | 708 | @max_minutes_to_run SMALLINT: 709 | 710 | The maximum number of minutes the workload is allowed to run before all child jobs are stopped. 711 | 712 | 713 | @job_prefix NVARCHAR(20): 714 | 715 | An optional parameter that can be used to prepend an identifier to the beginning of agent jobs created by the framework. 716 | The default behavior is to prepend nothing to the agent jobs. They will start with the @workload_identifier parameter value. 717 | 718 | 719 | @total_jobs_to_create SMALLINT: 720 | 721 | The number of "child" jobs that will be created. Use this to set maximum concurrency of the workload. 722 | This is a required parameter with no default value. Going above the CPU count of the server is not recommended. 723 | */ 724 | 725 | 726 | DECLARE @job_prefix_with_workload NVARCHAR(71), 727 | @child_job_name SYSNAME, 728 | @child_job_command NVARCHAR(4000), 729 | @cleanup_job_name SYSNAME, 730 | @cleanup_job_command NVARCHAR(4000), 731 | @job_description NVARCHAR(512), 732 | @current_time_local DATETIME2, 733 | @cleanup_start_date_as_int INT, 734 | @cleanup_start_time_as_int INT, 735 | @child_job_counter SMALLINT, 736 | @scheduler_table_name SYSNAME, 737 | @stop_request_table_name SYSNAME, 738 | @dynamic_sql_max NVARCHAR(MAX), 739 | @dynamic_sql_result_set_exists BIT, 740 | @procedure_exists BIT, 741 | @is_valid_common BIT, 742 | @error_message_common NVARCHAR(4000), 743 | @code_database_name SYSNAME = DB_NAME(), -- all code objects are required to exist on the same database and schema 744 | @code_schema_name SYSNAME = OBJECT_SCHEMA_NAME(@@PROCID); 745 | 746 | SET NOCOUNT ON; 747 | 748 | 749 | -- validate parameters 750 | -- check for outer transaction or for implicit transactions 751 | IF @@TRANCOUNT > 0 752 | BEGIN 753 | THROW 100000, N'Cannot call AgentJobMultiThread_CreateAgentJobs in an outer transaction because agent jobs may not start as expected.', 1 754 | RETURN; 755 | END; 756 | 757 | 758 | -- use stored procedure schema name and database if optional logging parameters aren't set 759 | SET @logging_database_name = ISNULL(@logging_database_name, DB_NAME()); 760 | SET @logging_schema_name = ISNULL(@logging_schema_name, OBJECT_SCHEMA_NAME(@@PROCID)); 761 | 762 | -- check common parameters 763 | EXEC [dbo].AgentJobMultiThread_Internal_ValidateCommonParameters 764 | @workload_identifier = @workload_identifier, 765 | @logging_database_name = @logging_database_name, 766 | @logging_schema_name = @logging_schema_name, 767 | @parent_start_time = @parent_start_time, 768 | @is_valid_OUT = @is_valid_common OUTPUT, 769 | @error_message_OUT = @error_message_common OUTPUT; 770 | 771 | IF @is_valid_common = 0 772 | BEGIN 773 | THROW 100010, @error_message_common, 1 774 | RETURN; 775 | END; 776 | 777 | 778 | -- validate @child_stored_procedure_name 779 | SET @procedure_exists = 0; 780 | EXEC [dbo].AgentJobMultiThread_Internal_CheckProcedureExists 781 | @procedure_name = @child_stored_procedure_name, 782 | @procedure_exists_OUT = @procedure_exists OUTPUT; 783 | 784 | IF @procedure_exists = 0 785 | BEGIN 786 | THROW 100020, N'Value for @child_stored_procedure_name does not exist as a stored procedure in the expected database and schema.', 1; 787 | RETURN; 788 | END; 789 | 790 | 791 | -- validate @cleanup_stored_procedure_name 792 | SET @procedure_exists = 0; 793 | EXEC [dbo].AgentJobMultiThread_Internal_CheckProcedureExists 794 | @procedure_name = @cleanup_stored_procedure_name, 795 | @procedure_exists_OUT = @procedure_exists OUTPUT; 796 | 797 | IF @procedure_exists = 0 798 | BEGIN 799 | THROW 100025, N'Value for @cleanup_stored_procedure_name does not exist as a stored procedure in the expected database and schema.', 1; 800 | RETURN; 801 | END; 802 | 803 | 804 | IF @max_minutes_to_run IS NULL OR @max_minutes_to_run <= 0 805 | BEGIN 806 | THROW 100030, N'The @max_minutes_to_run parameter of AgentJobMultiThread_CreateAgentJobs must be a positive number.', 1 807 | RETURN; 808 | END; 809 | 810 | 811 | IF @total_jobs_to_create IS NULL OR @total_jobs_to_create <= 0 812 | BEGIN 813 | THROW 100050, N'The @total_jobs_to_create parameter of AgentJobMultiThread_CreateAgentJobs must be a positive number.', 1 814 | RETURN; 815 | END; 816 | 817 | 818 | SET @job_prefix = ISNULL(N'', @job_prefix); 819 | SET @job_prefix_with_workload = @job_prefix + @workload_identifier; 820 | 821 | -- recreate *_Sessions_IDs_In_Use table so child jobs can try to get on their own schedulers 822 | SET @scheduler_table_name = @workload_identifier + N'_Sessions_IDs_In_Use'; 823 | 824 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'DROP TABLE IF EXISTS ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) 825 | + N'.' + QUOTENAME(@scheduler_table_name); 826 | 827 | EXEC sp_executesql @dynamic_sql_max; 828 | 829 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'CREATE TABLE ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) 830 | + N'.' + QUOTENAME(@scheduler_table_name) + N' ( 831 | scheduler_id INT NOT NULL, 832 | session_id SMALLINT NOT NULL 833 | )'; 834 | 835 | EXEC sp_executesql @dynamic_sql_max; 836 | 837 | 838 | -- create *_Last_Stop_Request table if it doesn't exist and insert a row 839 | SET @stop_request_table_name = @workload_identifier + N'_Last_Stop_Request'; 840 | 841 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'SELECT TOP (1) @dynamic_sql_result_set_exists_OUT = 1 842 | FROM ' + QUOTENAME(@logging_database_name) + N'.sys.tables t 843 | INNER JOIN ' + QUOTENAME(@logging_database_name) + N'.sys.schemas s ON t.[schema_id] = s.[schema_id] 844 | where t.name = @stop_request_table_name 845 | AND s.name = @logging_schema_name'; 846 | 847 | SET @dynamic_sql_result_set_exists = 0; 848 | EXEC sp_executesql @dynamic_sql_max, 849 | N'@dynamic_sql_result_set_exists_OUT BIT OUTPUT, @logging_schema_name SYSNAME, @stop_request_table_name SYSNAME', 850 | @logging_schema_name = @logging_schema_name, 851 | @stop_request_table_name = @stop_request_table_name, 852 | @dynamic_sql_result_set_exists_OUT = @dynamic_sql_result_set_exists OUTPUT; 853 | 854 | IF @dynamic_sql_result_set_exists = 0 855 | BEGIN 856 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'CREATE TABLE ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) 857 | + N'.' + QUOTENAME(@stop_request_table_name) + N' ( 858 | Stop_Request_UTC DATETIME2 NOT NULL 859 | )'; 860 | 861 | EXEC sp_executesql @dynamic_sql_max; 862 | 863 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'INSERT INTO ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) 864 | + N'.' + QUOTENAME(@stop_request_table_name) + N' WITH (TABLOCKX) (Stop_Request_UTC) 865 | VALUES(DATEADD(SECOND, -600, SYSUTCDATETIME()))'; 866 | 867 | EXEC sp_executesql @dynamic_sql_max; 868 | END; 869 | 870 | 871 | -- delete any child jobs left around from previous runs 872 | -- this can cause problems if a different user created the jobs last time, the jobs hit some kind of error, and the current 873 | -- executing user doesn't have permission to delete the jobs. 874 | -- I don't see a good way around this other than requiring possibly unacceptably high permissions for the calling user 875 | DECLARE @child_jobs_to_delete TABLE (job_name sysname); 876 | 877 | INSERT INTO @child_jobs_to_delete (job_name) 878 | SELECT sj.name 879 | FROM msdb.dbo.sysjobs sj 880 | INNER JOIN msdb.dbo.sysjobactivity sja ON sj.job_id = sja.job_id 881 | WHERE LEFT(sj.name, LEN(@job_prefix_with_workload)) = @job_prefix_with_workload 882 | AND sj.name LIKE '%[_]Child[_]%' 883 | OPTION (MAXDOP 1); 884 | 885 | DECLARE jobs_to_delete CURSOR FOR 886 | SELECT job_name 887 | FROM @child_jobs_to_delete; 888 | 889 | OPEN jobs_to_delete; 890 | 891 | FETCH NEXT FROM jobs_to_delete INTO @child_job_name; 892 | 893 | WHILE @@FETCH_STATUS = 0 894 | BEGIN 895 | EXEC msdb.dbo.sp_delete_job @job_name = @child_job_name; 896 | 897 | FETCH NEXT FROM jobs_to_delete INTO @child_job_name; 898 | END; 899 | CLOSE jobs_to_delete; 900 | DEALLOCATE jobs_to_delete; 901 | 902 | 903 | -- create clean up job to halt the child jobs if needed 904 | -- this should happen before the child jobs are created just in case something goes wrong 905 | SET @cleanup_job_name = @job_prefix_with_workload + N'_Cleanup'; 906 | 907 | SET @cleanup_job_command = N'EXEC ' + QUOTENAME(@code_schema_name) + N'.' + QUOTENAME(@cleanup_stored_procedure_name) + N' @logging_database_name=N''' + @logging_database_name 908 | + N''', 909 | @logging_schema_name=N''' + @logging_schema_name 910 | + N''', 911 | @parent_start_time=''' + CONVERT(NVARCHAR(30), @parent_start_time, 126) 912 | + N''', 913 | @max_minutes_to_run = ' + CAST(@max_minutes_to_run AS NVARCHAR(5)); 914 | 915 | SET @job_description = N'Clean up job created for ' + @workload_identifier + N' workload by stored procedure AgentJobMultiThread_CreateAgentJobs'; 916 | 917 | IF EXISTS (SELECT 1 FROM msdb.dbo.sysjobs WHERE name = @cleanup_job_name) 918 | BEGIN 919 | EXEC msdb.dbo.sp_delete_job @job_name = @cleanup_job_name; 920 | END; 921 | 922 | IF EXISTS (SELECT 1 FROM msdb.dbo.sysschedules WHERE name = @cleanup_job_name) 923 | BEGIN 924 | EXEC msdb.dbo.sp_delete_schedule @schedule_name = @cleanup_job_name, @force_delete = 1; 925 | END; 926 | 927 | EXEC msdb.dbo.sp_add_job @job_name = @cleanup_job_name, 928 | @description = @job_description, 929 | @delete_level = 0; -- cannot use delete level 1 when creating this job because it won't rerun 930 | 931 | EXEC msdb.dbo.sp_add_jobstep @job_name = @cleanup_job_name, 932 | @step_name = N'Clean up', 933 | @command = @cleanup_job_command, 934 | @database_name = @code_database_name; 935 | 936 | EXEC msdb.dbo.sp_add_jobserver @job_name = @cleanup_job_name; 937 | 938 | SET @current_time_local = SYSDATETIME(); 939 | 940 | -- :( 941 | SET @cleanup_start_date_as_int = CAST(CONVERT(NVARCHAR(30), DATEADD(SECOND, 61, @current_time_local), 112) AS INT); 942 | SET @cleanup_start_time_as_int = 10000 * DATEPART(HOUR, DATEADD(SECOND, 61, @current_time_local)) 943 | + 100 * DATEPART(MINUTE, DATEADD(SECOND, 61, @current_time_local)) 944 | + 1 * DATEPART(SECOND, DATEADD(SECOND, 61, @current_time_local)); 945 | 946 | EXEC msdb.dbo.sp_add_jobschedule @job_name = @cleanup_job_name, 947 | @name = @cleanup_job_name, 948 | @freq_type = 1, 949 | @freq_interval = 1, 950 | @active_start_date = @cleanup_start_date_as_int, 951 | @active_start_time = @cleanup_start_time_as_int; 952 | 953 | 954 | -- create child jobs to do the concurrent work 955 | SET @child_job_counter = 0; 956 | WHILE @child_job_counter < @total_jobs_to_create 957 | BEGIN 958 | SET @child_job_name = @job_prefix_with_workload + N'_Child_' + CAST(@child_job_counter AS NVARCHAR(5)); 959 | 960 | -- create stored procedure call T-SQL job command for worker jobs 961 | SET @child_job_command = N'EXEC ' + QUOTENAME(@code_schema_name) + N'.' + QUOTENAME(@child_stored_procedure_name) + N' @logging_database_name=N''' + @logging_database_name 962 | + N''', 963 | @logging_schema_name=N''' + @logging_schema_name 964 | + N''', 965 | @parent_start_time=''' + CONVERT(NVARCHAR(30), @parent_start_time, 126) 966 | + N''', 967 | @job_number = ' + CAST(@child_job_counter AS NVARCHAR(5)) 968 | + N', 969 | @job_attempt_number = 1'; 970 | 971 | SET @job_description = N'Child up job created for ' + @workload_identifier + N' workload by stored procedure AgentJobMultiThread_CreateAgentJobs'; 972 | 973 | EXEC msdb.dbo.sp_add_job @job_name = @child_job_name, 974 | @description = @job_description, 975 | @delete_level = 1; 976 | 977 | EXEC msdb.dbo.sp_add_jobstep @job_name = @child_job_name, 978 | @step_name = N'Do child work', 979 | @command = @child_job_command, 980 | @database_name = @code_database_name; 981 | 982 | EXEC msdb.dbo.sp_add_jobserver @job_name = @child_job_name; 983 | 984 | EXEC msdb.dbo.sp_start_job @job_name = @child_job_name; 985 | 986 | SET @child_job_counter = @child_job_counter + 1; 987 | END; 988 | 989 | RETURN; 990 | END; 991 | 992 | GO 993 | 994 | 995 | 996 | 997 | 998 | 999 | 1000 | CREATE OR ALTER PROCEDURE [dbo].AgentJobMultiThread_RescheduleChildJobIfNeeded ( 1001 | @workload_identifier NVARCHAR(50), 1002 | @logging_database_name SYSNAME = NULL, 1003 | @logging_schema_name SYSNAME = NULL, 1004 | @parent_start_time DATETIME2, 1005 | @child_stored_procedure_name SYSNAME, 1006 | @job_prefix NVARCHAR(20) = NULL, 1007 | @job_number SMALLINT, 1008 | @job_attempt_number SMALLINT, 1009 | @max_reschedule_attempts SMALLINT = 25, 1010 | @was_job_rescheduled_OUT BIT OUTPUT 1011 | ) 1012 | AS 1013 | BEGIN 1014 | /* 1015 | Procedure Name: AgentJobMultiThread_RescheduleChildJobIfNeeded 1016 | Author: Joe Obbish 1017 | Version: 1.0 1018 | Updates: https://github.com/jobbish-sql/SQL-Server-Multi-Thread 1019 | License: MIT 1020 | Purpose: 1021 | 1022 | This stored procedure should be called by the child workload procedure to determine if the agent job should halt 1023 | because the framework has rescheduled it. 1024 | 1025 | It is important to check the value of the @was_job_rescheduled_OUT parameter. 1026 | 1027 | The @child_stored_procedure_name stored procedure must exist in the same database and schema as this one and must have the following parameters: 1028 | @logging_database_name SYSNAME, 1029 | @logging_schema_name SYSNAME, 1030 | @parent_start_time DATETIME2, 1031 | @job_number SMALLINT, 1032 | @job_attempt_number SMALLINT 1033 | 1034 | For more information about child procedures execute the AgentJobMultiThread_Help stored procedure. 1035 | 1036 | 1037 | Parameter help: 1038 | 1039 | @workload_identifier NVARCHAR(50): 1040 | 1041 | An identifier to use for the workload. This identifier will be added to any agent jobs and tables 1042 | that are created by the framework. Use a consistent value for this identifier for the parent, child, and cleanup procedures. 1043 | 1044 | 1045 | @logging_database_name SYSNAME: 1046 | 1047 | Use this parameter if you want tables to be created in a different database than the database that 1048 | contains the AgentJobMultiThread stored procedures. 1049 | The default value is to use the database context of the AgentJobMultiThread stored procedures. 1050 | 1051 | 1052 | @logging_schema_name SYSNAME: 1053 | 1054 | Use this parameter if you want tables to be created in a different schema than the schema that 1055 | contains the AgentJobMultiThread stored procedures. 1056 | The default value is to use the schema context of the AgentJobMultiThread stored procedures. 1057 | 1058 | 1059 | @parent_start_time DATETIME2: 1060 | 1061 | The start time of the workload, preferably expressed in UTC. 1062 | Use a consistent value for this value for each iteration of the workload for the parent, child, and cleanup procedures. 1063 | 1064 | 1065 | @child_stored_procedure_name SYSNAME: 1066 | 1067 | The name of the stored procedure used to perform the "child" work for the workload. 1068 | This stored procedure must exist in the same database and schema as the AgentJobMultiThread. 1069 | Reference AgentJobMultiThread_Help if you need more information. 1070 | 1071 | 1072 | @job_prefix NVARCHAR(20): 1073 | 1074 | An optional parameter that can be used to prepend an identifier to the beginning of agent jobs created by the framework. 1075 | The default behavior is to prepend nothing to the agent jobs. They will start with the @workload_identifier parameter value. 1076 | 1077 | 1078 | @job_number SMALLINT: 1079 | 1080 | Used to enumerate jobs to achieve job name uniqueness, allow for application logging, and reschedule jobs 1081 | for CPU scheduler reasons as needed. 1082 | Will be present in the name of the agent job created. 1083 | 1084 | 1085 | @job_attempt_number SMALLINT: 1086 | 1087 | Used for internal purposes to reschedule jobs for CPU scheduler reasons as needed. 1088 | Will be present in the name of the agent job created. 1089 | 1090 | 1091 | @max_reschedule_attempts SMALLINT: 1092 | 1093 | The maximum amount of times a child job will delete and start itself in an attempt to get on its own CPU scheduler. 1094 | The default value is 25. 1095 | 0 is an allowed value if the caller does not want there to be CPU rescheduling. 1096 | Disabling may be a good idea if the child procedures do mostly parallel query work or the workload 1097 | is running on a busy server. 1098 | 1099 | 1100 | @was_job_rescheduled_OUT BIT OUTPUT: 1101 | 1102 | An output parameter that reports if the agent job was rescheduled in an attempt to get on its own CPU scheduler. 1103 | If this parameter is set to 0 then callers should allow the child procedure to continue. 1104 | If this parameter is set to 1 then callers should halt the child procedure. 1105 | */ 1106 | 1107 | 1108 | DECLARE @scheduler_id INT, 1109 | @dynamic_sql_max NVARCHAR(MAX), 1110 | @was_row_inserted_into_sessions_table BIT, 1111 | @job_prefix_with_workload NVARCHAR(71), 1112 | @child_job_name SYSNAME, 1113 | @child_job_command NVARCHAR(4000), 1114 | @job_description NVARCHAR(512), 1115 | @scheduler_table_name SYSNAME, 1116 | @procedure_exists BIT, 1117 | @is_valid_common BIT, 1118 | @error_message_common NVARCHAR(4000), 1119 | @code_database_name SYSNAME = DB_NAME(), -- all code objects are required to exist on the same database and schema 1120 | @code_schema_name SYSNAME = OBJECT_SCHEMA_NAME(@@PROCID); 1121 | 1122 | SET NOCOUNT ON; 1123 | 1124 | 1125 | -- validate parameters 1126 | -- check for outer transaction or for implicit transactions 1127 | IF @@TRANCOUNT > 0 1128 | BEGIN 1129 | THROW 100060, N'Cannot call AgentJobMultiThread_RescheduleChildJobIfNeeded in an outer transaction because agent jobs may not start as expected.', 1 1130 | RETURN; 1131 | END; 1132 | 1133 | 1134 | -- use stored procedure schema name and database if optional logging parameters aren't set 1135 | SET @logging_database_name = ISNULL(@logging_database_name, DB_NAME()); 1136 | SET @logging_schema_name = ISNULL(@logging_schema_name, OBJECT_SCHEMA_NAME(@@PROCID)); 1137 | 1138 | -- check common parameters 1139 | EXEC [dbo].AgentJobMultiThread_Internal_ValidateCommonParameters 1140 | @workload_identifier = @workload_identifier, 1141 | @logging_database_name = @logging_database_name, 1142 | @logging_schema_name = @logging_schema_name, 1143 | @parent_start_time = @parent_start_time, 1144 | @is_valid_OUT = @is_valid_common OUTPUT, 1145 | @error_message_OUT = @error_message_common OUTPUT; 1146 | 1147 | IF @is_valid_common = 0 1148 | BEGIN 1149 | THROW 100070, @error_message_common, 1 1150 | RETURN; 1151 | END; 1152 | 1153 | 1154 | -- validate @child_stored_procedure_name 1155 | SET @procedure_exists = 0; 1156 | EXEC [dbo].AgentJobMultiThread_Internal_CheckProcedureExists 1157 | @procedure_name = @child_stored_procedure_name, 1158 | @procedure_exists_OUT = @procedure_exists OUTPUT; 1159 | 1160 | IF @procedure_exists = 0 1161 | BEGIN 1162 | THROW 100080, N'Value for @child_stored_procedure_name does not exist as a stored procedure in the expected database and schema.', 1; 1163 | RETURN; 1164 | END; 1165 | 1166 | 1167 | IF @job_number IS NULL OR @job_number < 0 1168 | BEGIN 1169 | THROW 100100, N'The @job_number parameter of AgentJobMultiThread_RescheduleChildJobIfNeeded must be a non-negative number.', 1 1170 | RETURN; 1171 | END; 1172 | 1173 | 1174 | IF @job_attempt_number IS NULL OR @job_attempt_number < 0 1175 | BEGIN 1176 | THROW 100110, N'The @job_attempt_number parameter of AgentJobMultiThread_RescheduleChildJobIfNeeded must be a non-negative number.', 1 1177 | RETURN; 1178 | END; 1179 | 1180 | 1181 | IF @max_reschedule_attempts IS NULL OR @max_reschedule_attempts < 0 1182 | BEGIN 1183 | THROW 100120, N'The @max_reschedule_attempts parameter of AgentJobMultiThread_RescheduleChildJobIfNeeded must be a non-negative number.', 1 1184 | RETURN; 1185 | END; 1186 | 1187 | 1188 | SET @job_prefix = ISNULL(N'', @job_prefix); 1189 | SET @job_prefix_with_workload = @job_prefix + @workload_identifier; 1190 | SET @scheduler_table_name = @workload_identifier + N'_Sessions_IDs_In_Use'; 1191 | 1192 | SELECT @scheduler_id = scheduler_id 1193 | FROM sys.dm_os_tasks 1194 | where session_id = @@SPID 1195 | AND exec_context_id = 0 1196 | OPTION (MAXDOP 1); 1197 | 1198 | -- TABLOCKX hint to serialize, see no need for an application lock for this 1199 | SET @was_row_inserted_into_sessions_table = 0; 1200 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'INSERT INTO ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) 1201 | + N'.' + QUOTENAME(@scheduler_table_name) + N' WITH (TABLOCKX) 1202 | (scheduler_id, session_id) 1203 | SELECT @scheduler_id, @@SPID 1204 | WHERE NOT EXISTS ( 1205 | SELECT 1 1206 | FROM ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) + N'.' + QUOTENAME(@scheduler_table_name) + N' s WITH (TABLOCKX) 1207 | WHERE s.scheduler_id = @scheduler_id 1208 | ); 1209 | 1210 | SET @was_row_inserted_into_sessions_table_OUT = @@ROWCOUNT'; 1211 | 1212 | EXEC sp_executesql @dynamic_sql_max, 1213 | N'@scheduler_id INT, @was_row_inserted_into_sessions_table_OUT BIT OUTPUT', 1214 | @scheduler_id = @scheduler_id, 1215 | @was_row_inserted_into_sessions_table_OUT = @was_row_inserted_into_sessions_table OUTPUT; 1216 | 1217 | -- start a new job and quit if the job is sharing a scheduler and there are reattempts left 1218 | -- note that we log nothing to the scheduler table if we run out of reattempts. this should be ok given the long expected runtime of these procedures 1219 | -- in any case, if one of the procedures fails unexpectedly there isn't a clean way to clean out the row it inserted into the table 1220 | IF @was_row_inserted_into_sessions_table = 0 AND @job_attempt_number <= @max_reschedule_attempts 1221 | BEGIN 1222 | SET @child_job_name = @job_prefix_with_workload + N'_Child_' + CAST(@job_number AS NVARCHAR(5)) + N'_Attempt_' + CAST(@job_attempt_number AS NVARCHAR(5)); 1223 | 1224 | -- create stored procedure call T-SQL job command for worker jobs 1225 | SET @child_job_command = N'EXEC ' + QUOTENAME(@code_schema_name) + N'.' + QUOTENAME(@child_stored_procedure_name) + N' @logging_database_name=N''' + @logging_database_name 1226 | + N''', 1227 | @logging_schema_name=N''' + @logging_schema_name 1228 | + N''', 1229 | @parent_start_time=''' + CONVERT(NVARCHAR(30), @parent_start_time, 126) 1230 | + N''', 1231 | @job_number = ' + CAST(@job_number AS NVARCHAR(5)) 1232 | + N', 1233 | @job_attempt_number = ' + CAST(@job_attempt_number + 1 AS NVARCHAR(5)); 1234 | 1235 | SET @job_description = N'Child up job created for ' + @workload_identifier + N' workload by stored procedure AgentJobMultiThread_CreateAgentJobs'; 1236 | 1237 | EXEC msdb.dbo.sp_add_job @job_name = @child_job_name, 1238 | @description = @job_description, 1239 | @delete_level = 1; 1240 | 1241 | EXEC msdb.dbo.sp_add_jobstep @job_name = @child_job_name, 1242 | @step_name = N'Do child work', 1243 | @command = @child_job_command, 1244 | @database_name = @code_database_name; 1245 | 1246 | EXEC msdb.dbo.sp_add_jobserver @job_name = @child_job_name; 1247 | 1248 | EXEC msdb.dbo.sp_start_job @job_name = @child_job_name; 1249 | 1250 | SET @was_job_rescheduled_OUT = 1; 1251 | RETURN; 1252 | END; 1253 | 1254 | 1255 | SET @was_job_rescheduled_OUT = 0; 1256 | RETURN; 1257 | END; 1258 | 1259 | GO 1260 | 1261 | 1262 | 1263 | 1264 | 1265 | 1266 | 1267 | CREATE OR ALTER PROCEDURE [dbo].AgentJobMultiThread_ShouldChildJobHalt ( 1268 | @workload_identifier NVARCHAR(50), 1269 | @logging_database_name SYSNAME = NULL, 1270 | @logging_schema_name SYSNAME = NULL, 1271 | @parent_start_time DATETIME2, 1272 | @should_job_halt_OUT BIT OUTPUT 1273 | ) 1274 | AS 1275 | BEGIN 1276 | /* 1277 | Procedure Name: AgentJobMultiThread_ShouldChildJobHalt 1278 | Author: Joe Obbish 1279 | Version: 1.0 1280 | Updates: https://github.com/jobbish-sql/SQL-Server-Multi-Thread 1281 | License: MIT 1282 | Purpose: 1283 | 1284 | This stored procedure should be called by the child workload procedure to determine if the stored procedure should halt. 1285 | This is necessary because sometimes sp_stop_job will not stop an agent job. 1286 | It is important to check the value of the @should_job_halt_OUT parameter. 1287 | 1288 | 1289 | Parameter help: 1290 | 1291 | @workload_identifier NVARCHAR(50): 1292 | 1293 | An identifier to use for the workload. This identifier will be added to any agent jobs and tables 1294 | that are created by the framework. Use a consistent value for this identifier for the parent, child, and cleanup procedures. 1295 | 1296 | 1297 | @logging_database_name SYSNAME: 1298 | 1299 | Use this parameter if you want tables to be created in a different database than the database that 1300 | contains the AgentJobMultiThread stored procedures. 1301 | The default value is to use the database context of the AgentJobMultiThread stored procedures. 1302 | 1303 | 1304 | @logging_schema_name SYSNAME: 1305 | 1306 | Use this parameter if you want tables to be created in a different schema than the schema that 1307 | contains the AgentJobMultiThread stored procedures. 1308 | The default value is to use the schema context of the AgentJobMultiThread stored procedures. 1309 | 1310 | 1311 | @parent_start_time DATETIME2: 1312 | 1313 | The start time of the workload, preferably expressed in UTC. 1314 | Use a consistent value for this value for each iteration of the workload for the parent, child, and cleanup procedures. 1315 | 1316 | */ 1317 | 1318 | DECLARE @dynamic_sql_max NVARCHAR(MAX), 1319 | @stop_request_table_name SYSNAME; 1320 | 1321 | SET NOCOUNT ON; 1322 | 1323 | -- limited validation because this procedure may be called thousands of times 1324 | IF @workload_identifier IS NULL OR @parent_start_time IS NULL 1325 | BEGIN 1326 | THROW 100130, N'The @workload_identifier and @parent_start_time parameters of AgentJobMultiThread_ShouldChildJobHalt do not allow NULL.', 1 1327 | RETURN; 1328 | END; 1329 | 1330 | -- use stored procedure schema name and database if optional logging parameters aren't set 1331 | SET @logging_database_name = ISNULL(@logging_database_name, DB_NAME()); 1332 | SET @logging_schema_name = ISNULL(@logging_schema_name, OBJECT_SCHEMA_NAME(@@PROCID)); 1333 | 1334 | SET @stop_request_table_name = @workload_identifier + N'_Last_Stop_Request'; 1335 | 1336 | 1337 | SET @should_job_halt_OUT = 0; 1338 | 1339 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'SELECT TOP (1) @dynamic_sql_result_set_exists_OUT = 1 1340 | FROM ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) 1341 | + N'.' + QUOTENAME(@stop_request_table_name) + N' WITH (TABLOCKX) 1342 | WHERE @parent_start_time <= Stop_Request_UTC'; 1343 | 1344 | EXEC sp_executesql @dynamic_sql_max, 1345 | N'@dynamic_sql_result_set_exists_OUT BIT OUTPUT, @parent_start_time DATETIME2', 1346 | @parent_start_time = @parent_start_time, 1347 | @dynamic_sql_result_set_exists_OUT = @should_job_halt_OUT OUTPUT; 1348 | 1349 | RETURN; 1350 | END; 1351 | 1352 | GO 1353 | 1354 | 1355 | 1356 | 1357 | 1358 | 1359 | 1360 | CREATE OR ALTER PROCEDURE [dbo].AgentJobMultiThread_ShouldCleanupStopChildJobs ( 1361 | @workload_identifier NVARCHAR(50), 1362 | @parent_start_time DATETIME2, 1363 | @job_prefix NVARCHAR(20) = NULL, 1364 | @max_minutes_to_run SMALLINT, 1365 | @should_stop_jobs_OUT BIT OUTPUT 1366 | ) 1367 | AS 1368 | BEGIN 1369 | /* 1370 | Procedure Name: AgentJobMultiThread_ShouldCleanupStopChildJobs 1371 | Author: Joe Obbish 1372 | Version: 1.0 1373 | Updates: https://github.com/jobbish-sql/SQL-Server-Multi-Thread 1374 | License: MIT 1375 | Purpose: 1376 | 1377 | This stored procedure should be called by the cleanup workload procedure to determine if the workload has either completed its work 1378 | or hit the time limit. 1379 | 1380 | It is important to check the value of the @should_stop_jobs_OUT parameter to determine how the cleanup procedure should proceed. 1381 | 1382 | 1383 | Parameter help: 1384 | 1385 | @workload_identifier NVARCHAR(50): 1386 | 1387 | An identifier to use for the workload. This identifier will be added to any agent jobs and tables 1388 | that are created by the framework. Use a consistent value for this identifier for the parent, child, and cleanup procedures. 1389 | 1390 | 1391 | @parent_start_time DATETIME2: 1392 | 1393 | The start time of the workload, preferably expressed in UTC. 1394 | Use a consistent value for this value for each iteration of the workload for the parent, child, and cleanup procedures. 1395 | 1396 | 1397 | @job_prefix NVARCHAR(20): 1398 | 1399 | An optional parameter that can be used to prepend an identifier to the beginning of agent jobs created by the framework. 1400 | The default behavior is to prepend nothing to the agent jobs. They will start with the @workload_identifier parameter value. 1401 | 1402 | 1403 | @max_minutes_to_run SMALLINT: 1404 | 1405 | The maximum number of minutes the workload is allowed to run before all child jobs are stopped. 1406 | 1407 | 1408 | @should_stop_jobs_OUT BIT OUTPUT: 1409 | 1410 | An output parameter that reports if the cleanup procedure should continue. 1411 | The procedure checks if the time limit (see @max_minutes_to_run parameter) and checks if any child jobs are still running. 1412 | If this parameter is set to 0 then callers should halt the cleanup procedure. 1413 | If this parameter is set to 1 then callers should allow the cleanup procedure to continue. 1414 | */ 1415 | 1416 | DECLARE @job_prefix_with_workload NVARCHAR(71); 1417 | 1418 | SET NOCOUNT ON; 1419 | 1420 | SET @should_stop_jobs_OUT = 0; 1421 | 1422 | -- validate parameters 1423 | IF @workload_identifier IS NULL OR @parent_start_time IS NULL OR @max_minutes_to_run IS NULL 1424 | BEGIN 1425 | THROW 100140, N'Only the @job_prefix parameter of AgentJobMultiThread_ShouldCleanupStopChildJobs allows NULL.', 1 1426 | RETURN; 1427 | END; 1428 | 1429 | 1430 | IF @max_minutes_to_run <= 0 1431 | BEGIN 1432 | THROW 100150, N'The @max_minutes_to_run parameter of AgentJobMultiThread_ShouldCleanupStopChildJobs must be a positive value.', 1 1433 | RETURN; 1434 | END; 1435 | 1436 | 1437 | SET @job_prefix = ISNULL(N'', @job_prefix); 1438 | SET @job_prefix_with_workload = @job_prefix + @workload_identifier; 1439 | SET @should_stop_jobs_OUT = 0; 1440 | 1441 | IF SYSUTCDATETIME() > DATEADD(MINUTE, @max_minutes_to_run, @parent_start_time) 1442 | BEGIN 1443 | SET @should_stop_jobs_OUT = 1; 1444 | END 1445 | ELSE IF NOT EXISTS ( 1446 | SELECT sj.name 1447 | FROM msdb.dbo.sysjobs sj 1448 | INNER JOIN msdb.dbo.sysjobactivity sja ON sj.job_id = sja.job_id 1449 | WHERE sja.start_execution_date IS NOT NULL 1450 | AND sja.stop_execution_date IS NULL 1451 | AND LEFT(sj.name, LEN(@job_prefix_with_workload)) = @job_prefix_with_workload 1452 | AND sj.name <> @job_prefix_with_workload + N'_Cleanup' 1453 | AND session_id = (SELECT MAX(session_id) FROM msdb.dbo.sysjobactivity) 1454 | ) 1455 | BEGIN 1456 | SET @should_stop_jobs_OUT = 1; 1457 | END; 1458 | 1459 | 1460 | RETURN; 1461 | END; 1462 | 1463 | GO 1464 | 1465 | 1466 | 1467 | 1468 | 1469 | 1470 | 1471 | CREATE OR ALTER PROCEDURE [dbo].AgentJobMultiThread_CleanupChildJobs ( 1472 | @workload_identifier NVARCHAR(50), 1473 | @logging_database_name SYSNAME = NULL, 1474 | @logging_schema_name SYSNAME = NULL, 1475 | @job_prefix NVARCHAR(20) = NULL, 1476 | @child_job_error_count_OUT INT OUTPUT, 1477 | @cleanup_error_message_OUT NVARCHAR(4000) OUTPUT 1478 | ) 1479 | AS 1480 | BEGIN 1481 | /* 1482 | Procedure Name: AgentJobMultiThread_CleanupChildJobs 1483 | Author: Joe Obbish 1484 | Version: 1.0 1485 | Updates: https://github.com/jobbish-sql/SQL-Server-Multi-Thread 1486 | License: MIT 1487 | Purpose: 1488 | 1489 | This stored procedure should be called by the cleanup workload procedure to stop any jobs that are still running. 1490 | The output parameters provide useful troubleshooting information but they are not required to check. 1491 | 1492 | 1493 | Parameter help: 1494 | 1495 | @workload_identifier NVARCHAR(50): 1496 | 1497 | An identifier to use for the workload. This identifier will be added to any agent jobs and tables 1498 | that are created by the framework. Use a consistent value for this identifier for the parent, child, and cleanup procedures. 1499 | 1500 | 1501 | @logging_database_name SYSNAME: 1502 | 1503 | Use this parameter if you want tables to be created in a different database than the database that 1504 | contains the AgentJobMultiThread stored procedures. 1505 | The default value is to use the database context of the AgentJobMultiThread stored procedures. 1506 | 1507 | 1508 | @logging_schema_name SYSNAME: 1509 | 1510 | Use this parameter if you want tables to be created in a different schema than the schema that 1511 | contains the AgentJobMultiThread stored procedures. 1512 | The default value is to use the schema context of the AgentJobMultiThread stored procedures. 1513 | 1514 | 1515 | @job_prefix NVARCHAR(20): 1516 | 1517 | An optional parameter that can be used to prepend an identifier to the beginning of agent jobs created by the framework. 1518 | The default behavior is to prepend nothing to the agent jobs. They will start with the @workload_identifier parameter value. 1519 | 1520 | 1521 | @child_job_error_count_OUT INT OUTPUT: 1522 | 1523 | An output parameter that reports the number of child jobs that reported some kind of error and the number of errors 1524 | witnessed while stopping jobs. 1525 | This parameter can be ignored by the caller but it's recommended to log this information somewhere for troubleshooting purposes. 1526 | Note that this error count cannot be complete due to how logging works for agent jobs. 1527 | Child job runtime errors can only be found if the child job quits on its own as opposed to being stopped. 1528 | 1529 | 1530 | @cleanup_error_message_OUT OUTPUT: 1531 | 1532 | An output parameter that contains an error message encountered while stopping jobs. 1533 | This parameter can be ignored by the caller but it's recommended to log this information somewhere for troubleshooting purposes. 1534 | */ 1535 | 1536 | DECLARE @job_prefix_with_workload NVARCHAR(71), 1537 | @job_name_to_stop SYSNAME, 1538 | @dynamic_sql_max NVARCHAR(MAX), 1539 | @stop_request_table_name SYSNAME, 1540 | @is_valid_common BIT, 1541 | @error_message_common NVARCHAR(4000); 1542 | 1543 | SET NOCOUNT ON; 1544 | 1545 | 1546 | -- use stored procedure schema name and database if optional logging parameters aren't set 1547 | SET @logging_database_name = ISNULL(@logging_database_name, DB_NAME()); 1548 | SET @logging_schema_name = ISNULL(@logging_schema_name, OBJECT_SCHEMA_NAME(@@PROCID)); 1549 | 1550 | -- validate parameters 1551 | -- check common parameters 1552 | EXEC [dbo].AgentJobMultiThread_Internal_ValidateCommonParameters 1553 | @workload_identifier = @workload_identifier, 1554 | @logging_database_name = @logging_database_name, 1555 | @logging_schema_name = @logging_schema_name, 1556 | @parent_start_time = '20200101', -- dummy value 1557 | @is_valid_OUT = @is_valid_common OUTPUT, 1558 | @error_message_OUT = @error_message_common OUTPUT; 1559 | 1560 | IF @is_valid_common = 0 1561 | BEGIN 1562 | THROW 100160, @error_message_common, 1 1563 | RETURN; 1564 | END; 1565 | 1566 | 1567 | SET @job_prefix = ISNULL(N'', @job_prefix); 1568 | SET @job_prefix_with_workload = @job_prefix + @workload_identifier; 1569 | SET @child_job_error_count_OUT = 0; 1570 | SET @stop_request_table_name = @workload_identifier + N'_Last_Stop_Request'; 1571 | 1572 | 1573 | -- log stop request in tables for child jobs to check if needed. sometimes jobs do not respect sp_stop_job calls 1574 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'UPDATE ' + QUOTENAME(@logging_database_name) + N'.' + QUOTENAME(@logging_schema_name) 1575 | + N'.' + QUOTENAME(@stop_request_table_name) + N' WITH (TABLOCKX) 1576 | SET Stop_Request_UTC = SYSUTCDATETIME()'; 1577 | 1578 | EXEC sp_executesql @dynamic_sql_max; 1579 | 1580 | 1581 | DECLARE @active_jobs TABLE (job_name sysname); 1582 | 1583 | INSERT INTO @active_jobs (job_name) 1584 | SELECT sj.name 1585 | FROM msdb.dbo.sysjobs sj 1586 | INNER JOIN msdb.dbo.sysjobactivity sja ON sj.job_id = sja.job_id 1587 | WHERE sja.start_execution_date IS NOT NULL 1588 | AND sja.stop_execution_date IS NULL 1589 | AND LEFT(sj.name, LEN(@job_prefix_with_workload)) = @job_prefix_with_workload 1590 | AND sj.name <> @job_prefix_with_workload + N'_Cleanup' 1591 | AND session_id = (SELECT MAX(session_id) FROM msdb.dbo.sysjobactivity) 1592 | OPTION (MAXDOP 1); 1593 | 1594 | DECLARE jobs_to_stop CURSOR FOR 1595 | SELECT job_name 1596 | FROM @active_jobs; 1597 | 1598 | OPEN jobs_to_stop; 1599 | 1600 | FETCH NEXT FROM jobs_to_stop INTO @job_name_to_stop; 1601 | 1602 | WHILE @@FETCH_STATUS = 0 1603 | BEGIN 1604 | BEGIN TRY 1605 | EXEC msdb.dbo.sp_stop_job @job_name = @job_name_to_stop; 1606 | 1607 | -- as far as I can tell if a job is stopped then any errors during execution are not recorded to any of the history tables 1608 | -- it would be nice to not delete the job if there was an unexpected error in the child job 1609 | EXEC msdb.dbo.sp_delete_job @job_name = @job_name_to_stop; 1610 | END TRY 1611 | BEGIN CATCH 1612 | -- job might have stopped on its own before we could call stop, so ignore some errors: 1613 | -- "The specified @job_name ('%') does not exist." 1614 | -- "SQLServerAgent Error: Request to stop job % (from %) refused because the job is not currently running." 1615 | IF ERROR_NUMBER() NOT IN (22022, 14262) 1616 | BEGIN 1617 | SET @child_job_error_count_OUT = @child_job_error_count_OUT + 1; 1618 | SET @cleanup_error_message_OUT = ERROR_MESSAGE(); -- only keep one error, not worth the effort to get them all 1619 | END; 1620 | END CATCH; 1621 | 1622 | FETCH NEXT FROM jobs_to_stop INTO @job_name_to_stop; 1623 | END; 1624 | 1625 | CLOSE jobs_to_stop; 1626 | DEALLOCATE jobs_to_stop; 1627 | 1628 | 1629 | -- add in errors from child jobs (these wouldn't have been stopped by the cursor) 1630 | SELECT @child_job_error_count_OUT = @child_job_error_count_OUT + COUNT_BIG(*) 1631 | FROM msdb.dbo.sysjobs sj 1632 | INNER JOIN msdb.dbo.sysjobhistory sjh ON sj.job_id = sjh.job_id 1633 | WHERE sjh.sql_message_id <> 0 1634 | AND LEFT(sj.name, LEN(@job_prefix)) = @job_prefix 1635 | AND sj.name <> @job_prefix_with_workload + N'_Cleanup'; 1636 | 1637 | 1638 | RETURN; 1639 | END; 1640 | 1641 | GO 1642 | 1643 | 1644 | 1645 | 1646 | 1647 | 1648 | 1649 | CREATE OR ALTER PROCEDURE [dbo].AgentJobMultiThread_FinalizeCleanup ( 1650 | @workload_identifier NVARCHAR(50), 1651 | @job_prefix NVARCHAR(20) = NULL, 1652 | @retry_cleanup BIT 1653 | ) 1654 | AS 1655 | BEGIN 1656 | /* 1657 | Procedure Name: AgentJobMultiThread_FinalizeCleanup 1658 | Author: Joe Obbish 1659 | Version: 1.0 1660 | Updates: https://github.com/jobbish-sql/SQL-Server-Multi-Thread 1661 | License: MIT 1662 | Purpose: 1663 | 1664 | This stored procedure should be called by the cleanup workload procedure right before it quits. 1665 | 1666 | If @retry_cleanup = 1 then the cleanup will try again in about one minute. 1667 | If @retry_cleanup = 0 then the cleanup will remove its agent job unless an error occurred during execution. 1668 | 1669 | 1670 | Parameter help: 1671 | 1672 | @workload_identifier NVARCHAR(50): 1673 | 1674 | An identifier to use for the workload. This identifier will be added to any agent jobs and tables 1675 | that are created by the framework. Use a consistent value for this identifier for the parent, child, and cleanup procedures. 1676 | 1677 | 1678 | @job_prefix NVARCHAR(20): 1679 | 1680 | An optional parameter that can be used to prepend an identifier to the beginning of agent jobs created by the framework. 1681 | The default behavior is to prepend nothing to the agent jobs. They will start with the @workload_identifier parameter value. 1682 | 1683 | @retry_cleanup BIT: 1684 | 1685 | Set this parameter to 1 if the cleanup procedure has done its work and there is no longer a need to run it. 1686 | Set this parameter to 0 if the cleanup procedure halted early based on the output parameter of 1687 | AgentJobMultiThread_ShouldCleanupStopChildJobs and needs to try again in a minute. 1688 | */ 1689 | 1690 | DECLARE @next_start_time_local DATETIME, 1691 | @cleanup_job_name SYSNAME, 1692 | @next_cleanup_start_date_int INT, 1693 | @next_cleanup_start_time_int INT, 1694 | @error_message NVARCHAR(4000) 1695 | 1696 | SET NOCOUNT ON; 1697 | 1698 | 1699 | -- validate parameters 1700 | IF @workload_identifier IS NULL OR @retry_cleanup IS NULL 1701 | BEGIN 1702 | THROW 100180, N'The @workload_identifier and @retry_cleanup parameters of AgentJobMultiThread_FinalizeCleanup do not allow NULL.', 1 1703 | RETURN; 1704 | END; 1705 | 1706 | SET @job_prefix = ISNULL(N'', @job_prefix); 1707 | SET @cleanup_job_name = @job_prefix + @workload_identifier + N'_Cleanup'; 1708 | 1709 | IF @retry_cleanup = 0 1710 | BEGIN 1711 | -- delete schedule since it is no longer needed 1712 | BEGIN TRY 1713 | EXEC msdb.dbo.sp_delete_schedule @schedule_name = @cleanup_job_name, @force_delete = 1; 1714 | END TRY 1715 | BEGIN CATCH 1716 | -- can sometimes get into a state where an initial error results in errors rerunning this procedure, so ignore an error here if the step was already deleted 1717 | -- The specified @schedule_name (%) does not exist. 1718 | IF ERROR_NUMBER() NOT IN (14262) 1719 | BEGIN 1720 | SET @error_message = ERROR_MESSAGE(); 1721 | THROW 100190, @error_message, 1; 1722 | END; 1723 | END CATCH; 1724 | 1725 | -- leave job around if there are errors 1726 | EXEC msdb.dbo.sp_update_job @job_name=@cleanup_job_name, @delete_level=1; 1727 | END 1728 | ELSE 1729 | BEGIN 1730 | -- change the schedule to run once again a minute from now. seemed easier than trying to set a schedule to run every minute 1731 | SET @next_start_time_local = DATEADD(SECOND, 60, SYSDATETIME()); 1732 | 1733 | SET @next_cleanup_start_date_int = CAST(CONVERT(NVARCHAR(30), @next_start_time_local, 112) AS INT); 1734 | SET @next_cleanup_start_time_int = 10000 * DATEPART(HOUR, @next_start_time_local) 1735 | + 100 * DATEPART(MINUTE, @next_start_time_local) 1736 | + 1 * DATEPART(SECOND, @next_start_time_local); 1737 | 1738 | EXEC msdb.dbo.sp_update_schedule @name = @cleanup_job_name, 1739 | @active_start_date = @next_cleanup_start_date_int, 1740 | @active_start_time = @next_cleanup_start_time_int; 1741 | 1742 | END; 1743 | 1744 | RETURN; 1745 | END; 1746 | 1747 | GO 1748 | -------------------------------------------------------------------------------- /demo/ThreadingDemo.sql: -------------------------------------------------------------------------------- 1 | SET ANSI_NULLS ON; 2 | SET ANSI_PADDING ON; 3 | SET ANSI_WARNINGS ON; 4 | SET ARITHABORT ON; 5 | SET CONCAT_NULL_YIELDS_NULL ON; 6 | SET QUOTED_IDENTIFIER ON; 7 | GO 8 | 9 | 10 | CREATE OR ALTER PROCEDURE [dbo].ThreadingDemoParent ( 11 | @max_minutes_to_run SMALLINT, 12 | @total_jobs_to_create SMALLINT, 13 | @child_MAXDOP SMALLINT = NULL 14 | ) 15 | AS 16 | BEGIN 17 | /* 18 | Procedure Name: ThreadingDemoParent 19 | Author: Joe Obbish 20 | Version: 1.0 21 | Updates: https://github.com/jobbish-sql/SQL-Server-Multi-Thread 22 | License: MIT 23 | Purpose: 24 | 25 | Simple example to show how to use the AgentJobMultiThread framework. 26 | This functions as the parent procedure for the workload. 27 | It performs any necessary prep work such as creating tables, populating queues, and creates the child jobs. 28 | 29 | Minimum permissions required to run: 30 | * VIEW_SERVER_STATE 31 | * SQLAgentUserRole 32 | * db_datareader on the msdb database 33 | * execute procedure on this database 34 | * db_ddladmin, db_datawriter, db_datareader on this database 35 | 36 | 37 | Parameter help: 38 | 39 | @max_minutes_to_run SMALLINT: 40 | 41 | The maximum number of minutes for the ThreadingDemo workload to run before all jobs are terminated. 42 | 43 | 44 | @total_jobs_to_create SMALLINT: 45 | 46 | Specify the maximum number of concurrent child procedures that can be run. 47 | This is a required parameter with no default value. Going above the CPU count of the server is not recommended. 48 | 49 | 50 | @child_MAXDOP SMALLINT: 51 | 52 | Set this to add a query level MAXDOP hint to code that executes in the child procedures. 53 | 54 | 55 | */ 56 | 57 | DECLARE @workload_identifier NVARCHAR(50) = N'ThreadingDemo', 58 | @parent_start_time DATETIME2 = SYSUTCDATETIME(), 59 | @child_stored_procedure_name SYSNAME = N'ThreadingDemoChild', 60 | @cleanup_stored_procedure_name SYSNAME = N'ThreadingDemoCleanup', 61 | @logging_schema_name SYSNAME, 62 | @is_valid BIT, 63 | @error_message NVARCHAR(4000); 64 | 65 | SET NOCOUNT ON; 66 | 67 | -- NOTE: All code and table objects should exist in the same database and schema. 68 | -- This example code does not support putting tables in a different database or schema to improve readability. 69 | 70 | 71 | -- use stored procedure schema 72 | SET @logging_schema_name = OBJECT_SCHEMA_NAME(@@PROCID); 73 | 74 | 75 | -- *** STEP 1: run standard validation *** 76 | SET @is_valid = 1; 77 | EXEC [dbo].AgentJobMultiThread_InitialValidation 78 | @workload_identifier = @workload_identifier, 79 | @parent_start_time = @parent_start_time, 80 | @child_stored_procedure_name = @child_stored_procedure_name, 81 | @cleanup_stored_procedure_name = @cleanup_stored_procedure_name, 82 | @max_minutes_to_run = @max_minutes_to_run, 83 | @total_jobs_to_create = @total_jobs_to_create, 84 | @is_valid_OUT = @is_valid OUTPUT, 85 | @error_message_OUT = @error_message OUTPUT; 86 | 87 | IF @is_valid = 0 88 | BEGIN 89 | THROW 90000, @error_message, 1; 90 | RETURN; 91 | END; 92 | 93 | 94 | 95 | -- *** STEP 2: run custom validation specific to this procedure *** 96 | IF @child_MAXDOP < 0 97 | BEGIN 98 | THROW 90010, N'@child_MAXDOP parameter, if set, must be a non-negative integer', 1; 99 | RETURN; 100 | END; 101 | 102 | 103 | 104 | -- *** STEP 3: do setup work including creating and populating needed tables *** 105 | 106 | -- create a summary table if it doesn't exist 107 | -- summary tables are useful to store statistics from the run as well as to pass additional parameters to the child procedure 108 | -- adding the parameters to the command text directly can introduce a SQL injection risk 109 | IF NOT EXISTS ( 110 | SELECT 1 111 | FROM sys.tables t 112 | INNER JOIN sys.schemas s ON t.[schema_id] = s.[schema_id] 113 | where t.name = N'ThreadingDemo_Summary' 114 | AND s.name = @logging_schema_name 115 | ) 116 | BEGIN 117 | CREATE TABLE [dbo].ThreadingDemo_Summary ( 118 | Summary_Start_Time_UTC DATETIME2 NOT NULL, 119 | Summary_End_Time_UTC DATETIME2 NULL, 120 | Total_Checksums BIGINT NULL, 121 | Maximum_Checksum_Value INT NULL, 122 | Max_Minutes_To_Run SMALLINT NOT NULL, 123 | Total_Jobs_To_Create SMALLINT NOT NULL, 124 | Child_MAXDOP SMALLINT NULL, 125 | Approximate_Error_Count INT NULL, 126 | Cleanup_Error_Text NVARCHAR(4000) NULL 127 | ); 128 | 129 | CREATE CLUSTERED INDEX CI_ThreadingDemo_Summary ON [dbo].ThreadingDemo_Summary (Summary_Start_Time_UTC); 130 | END; 131 | 132 | -- insert into summary table 133 | INSERT INTO [dbo].ThreadingDemo_Summary ( 134 | Summary_Start_Time_UTC 135 | , Max_Minutes_To_Run 136 | , Total_Jobs_To_Create 137 | , Child_MAXDOP 138 | ) 139 | VALUES 140 | ( 141 | @parent_start_time 142 | , @max_minutes_to_run 143 | , @total_jobs_to_create 144 | , @child_MAXDOP 145 | ); 146 | 147 | 148 | -- drop and recreate a log table for the child jobs to report outcomes from their units of work 149 | DROP TABLE IF EXISTS [dbo].ThreadingDemo_Child_Log; 150 | 151 | CREATE TABLE [dbo].ThreadingDemo_Child_Log ( 152 | Summary_Start_Time_UTC DATETIME2 NOT NULL, 153 | Job_Number SMALLINT NOT NULL, 154 | Batch_Id BIGINT NOT NULL, 155 | Checksum_Count BIGINT NOT NULL, 156 | Maximum_Checksum_Value INT NOT NULL, 157 | Query_Start_Time_UTC DATETIME2 NOT NULL, 158 | Query_Complete_Time_UTC DATETIME2 NULL, 159 | Session_Id INT NOT NULL, 160 | Error_Text NVARCHAR(4000) NULL 161 | ); 162 | 163 | 164 | -- create a queue to hold units of work for the child jobs to pull from 165 | -- ideally as much heavy lifting is done in the child jobs as possible compared to this procedure 166 | DROP TABLE IF EXISTS [dbo].ThreadingDemo_Work_Queue; 167 | 168 | CREATE TABLE [dbo].ThreadingDemo_Work_Queue ( 169 | Batch_Id BIGINT 170 | ); 171 | 172 | 173 | -- insert work to do into queue table 174 | INSERT INTO [dbo].ThreadingDemo_Work_Queue WITH (TABLOCKX) (Batch_Id) 175 | SELECT TOP (100000) ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) 176 | FROM master..spt_values t1 177 | CROSS JOIN master..spt_values t2 178 | OPTION (MAXDOP 1); 179 | 180 | 181 | 182 | -- *** STEP 4: create the agent jobs *** 183 | EXEC [dbo].AgentJobMultiThread_CreateAgentJobs 184 | @workload_identifier = @workload_identifier, 185 | @parent_start_time = @parent_start_time, 186 | @child_stored_procedure_name = @child_stored_procedure_name, 187 | @cleanup_stored_procedure_name = @cleanup_stored_procedure_name, 188 | @max_minutes_to_run = @max_minutes_to_run, 189 | @total_jobs_to_create = @total_jobs_to_create; 190 | 191 | 192 | RETURN; 193 | END; 194 | 195 | GO 196 | 197 | 198 | 199 | 200 | 201 | 202 | 203 | CREATE OR ALTER PROCEDURE [dbo].ThreadingDemoChild ( 204 | @logging_database_name SYSNAME, 205 | @logging_schema_name SYSNAME, 206 | @parent_start_time DATETIME2, 207 | @job_number SMALLINT, 208 | @job_attempt_number SMALLINT 209 | ) 210 | AS 211 | BEGIN 212 | /* 213 | Procedure Name: ThreadingDemoChild 214 | Author: Joe Obbish 215 | Version: 1.0 216 | Updates: https://github.com/jobbish-sql/SQL-Server-Multi-Thread 217 | License: MIT 218 | Purpose: 219 | 220 | This functions as the child procedure for the workload. 221 | It gets work off a queue, performs that work, logs it to a table, and gets the next piece of work. 222 | The SELECT queries that do no useful work by design (they perform CHECKSUM and save off results). 223 | 224 | 225 | Parameter help: 226 | 227 | The parameters must exactly match what is required by the AgentJobMultiThread framework. 228 | See the documentation for the framework for more information. 229 | 230 | */ 231 | 232 | DECLARE 233 | @workload_identifier NVARCHAR(50) = N'ThreadingDemo', 234 | @child_stored_procedure_name SYSNAME = N'ThreadingDemoChild', 235 | @was_job_rescheduled BIT, 236 | @dynamic_sql_max NVARCHAR(MAX) = CAST(N'' AS NVARCHAR(MAX)), 237 | @child_MAXDOP SMALLINT, 238 | @error_message NVARCHAR(4000), 239 | @all_available_work_complete BIT, 240 | @batch_id BIGINT, 241 | @checksum_count BIGINT, 242 | @max_checksum_value INT, 243 | @query_start_time DATETIME2, 244 | @query_end_time DATETIME2, 245 | @should_job_stop BIT, 246 | @row_check BIT; 247 | 248 | SET NOCOUNT ON; 249 | 250 | 251 | -- *** STEP 1: if needed, get any needed additional parameters from a summary table *** 252 | SELECT 253 | @row_check = 1 254 | , @child_MAXDOP = Child_MAXDOP 255 | FROM [dbo].ThreadingDemo_Summary 256 | WHERE Summary_Start_Time_UTC = @parent_start_time; 257 | 258 | 259 | -- there was likely a problem with the parent procedure if @row_check is NULL 260 | IF @row_check IS NULL 261 | BEGIN 262 | SET @error_message = N'Cannot find expected row in ThreadingDemo_Summary table. Look for an error logged by the ThreadingDemoParent stored procedure.'; 263 | THROW 90020, @error_message, 1; 264 | RETURN; 265 | END; 266 | 267 | 268 | 269 | -- *** STEP 2: check if procedure should quit due to rescheduling *** 270 | SET @was_job_rescheduled = 0; 271 | EXEC dbo.AgentJobMultiThread_RescheduleChildJobIfNeeded 272 | @workload_identifier = @workload_identifier, 273 | @parent_start_time = @parent_start_time, 274 | @child_stored_procedure_name = @child_stored_procedure_name, 275 | @job_number = @job_number, 276 | @job_attempt_number = @job_attempt_number, 277 | @was_job_rescheduled_OUT = @was_job_rescheduled OUTPUT; 278 | 279 | IF @was_job_rescheduled = 1 280 | BEGIN 281 | RETURN; 282 | END; 283 | 284 | 285 | 286 | -- *** STEP 3: find a unit of work *** 287 | DECLARE @hold_deleted_row TABLE ( 288 | Batch_Id BIGINT NOT NULL 289 | ); 290 | 291 | SET @should_job_stop = 0; 292 | SET @all_available_work_complete = 0; 293 | WHILE @all_available_work_complete = 0 294 | BEGIN 295 | SET @batch_id = NULL; 296 | 297 | DELETE FROM @hold_deleted_row; 298 | 299 | DELETE TOP (1) FROM [dbo].ThreadingDemo_Work_Queue 300 | WITH (TABLOCKX) 301 | OUTPUT deleted.Batch_Id INTO @hold_deleted_row; 302 | 303 | SELECT @batch_id = Batch_Id 304 | FROM @hold_deleted_row; 305 | 306 | -- if NULL then there is no more work to do 307 | IF @batch_id IS NULL 308 | BEGIN 309 | SET @all_available_work_complete = 1; 310 | END 311 | ELSE 312 | BEGIN 313 | -- *** STEP 4: complete the unit of work *** 314 | SET @error_message = NULL; 315 | SET @query_start_time = SYSUTCDATETIME(); 316 | 317 | SET @dynamic_sql_max = CAST(N'' AS NVARCHAR(MAX)) + N'SELECT 318 | @checksum_count_OUT = COUNT_BIG(*) 319 | , @max_checksum_value_OUT = MAX(CHECKSUM(CAST(@batch_id AS BIGINT) + t1.[number] + t2.[number])) 320 | FROM master..spt_values t1 321 | CROSS JOIN master..spt_values t2' 322 | + CASE WHEN @child_MAXDOP IS NOT NULL THEN N' OPTION(MAXDOP ' + CAST(@child_MAXDOP AS NVARCHAR(5)) + N')' ELSE N'' END; 323 | 324 | BEGIN TRY 325 | EXEC sp_executesql @dynamic_sql_max, 326 | N'@checksum_count_OUT BIGINT OUTPUT, @max_checksum_value_OUT INT OUTPUT, @batch_id INT', 327 | @checksum_count_OUT = @checksum_count OUTPUT, 328 | @max_checksum_value_OUT = @max_checksum_value OUTPUT, 329 | @batch_id = @batch_id; 330 | END TRY 331 | BEGIN CATCH 332 | SET @error_message = ERROR_MESSAGE(); 333 | END CATCH; 334 | 335 | SET @query_end_time = SYSUTCDATETIME(); 336 | 337 | INSERT INTO [dbo].ThreadingDemo_Child_Log 338 | ( 339 | Summary_Start_Time_UTC 340 | , Job_Number 341 | , Batch_Id 342 | , Checksum_Count 343 | , Maximum_Checksum_Value 344 | , Query_Start_Time_UTC 345 | , Query_Complete_Time_UTC 346 | , Session_Id 347 | , Error_Text 348 | ) 349 | VALUES ( 350 | @parent_start_time 351 | , @job_number 352 | , @batch_id 353 | , @checksum_count 354 | , @max_checksum_value 355 | , @query_start_time 356 | , @query_end_time 357 | , @@SPID 358 | , @error_message 359 | ); 360 | 361 | 362 | 363 | -- *** STEP 5: call AgentJobMultiThread_ShouldChildJobHalt frequently *** 364 | EXEC [dbo].AgentJobMultiThread_ShouldChildJobHalt 365 | @workload_identifier = @workload_identifier, 366 | @parent_start_time = @parent_start_time, 367 | @should_job_halt_OUT = @should_job_stop OUTPUT; 368 | 369 | IF @should_job_stop = 1 370 | BEGIN 371 | SET @all_available_work_complete = 1; 372 | END; 373 | END; 374 | END; 375 | 376 | RETURN; 377 | END; 378 | 379 | GO 380 | 381 | 382 | 383 | 384 | 385 | 386 | 387 | CREATE OR ALTER PROCEDURE [dbo].ThreadingDemoCleanup ( 388 | @logging_database_name SYSNAME, 389 | @logging_schema_name SYSNAME, 390 | @parent_start_time DATETIME2, 391 | @max_minutes_to_run SMALLINT 392 | ) 393 | AS 394 | BEGIN 395 | /* 396 | Procedure Name: ThreadingDemoCleanup 397 | Author: Joe Obbish 398 | Version: 1.0 399 | Updates: https://github.com/jobbish-sql/SQL-Server-Multi-Thread 400 | License: MIT 401 | Purpose: 402 | 403 | This functions as the cleanup procedure for the workload. 404 | It calls APIs to remove any currently running jobs. 405 | It also writes to a summary table which is custom code for this workload. 406 | 407 | Parameter help: 408 | 409 | The parameters must exactly match what is required by the AgentJobMultiThread framework. 410 | See the documentation for the framework for more information. 411 | 412 | */ 413 | 414 | DECLARE @workload_identifier NVARCHAR(50) = N'ThreadingDemo', 415 | @stop_jobs BIT, 416 | @error_message NVARCHAR(4000), 417 | @error_count_from_cleanup INT, 418 | @error_message_from_cleanup NVARCHAR(4000), 419 | @row_check BIT; 420 | 421 | SET NOCOUNT ON; 422 | 423 | 424 | -- *** STEP 1: if needed, get any needed additional parameters from a summary table *** 425 | SELECT 426 | @row_check = 1 427 | FROM [dbo].ThreadingDemo_Summary 428 | WHERE Summary_Start_Time_UTC = @parent_start_time; 429 | 430 | 431 | -- there was likely a problem with the parent procedure if @row_check is NULL 432 | IF @row_check IS NULL 433 | BEGIN 434 | SET @error_message = N'Cannot find expected row in ThreadingDemo_Summary table. Look for an error logged by the ThreadingDemoParent stored procedure.'; 435 | THROW 90030, @error_message, 1; 436 | RETURN; 437 | END; 438 | 439 | 440 | 441 | SET @stop_jobs = 0; 442 | -- *** STEP 2: call AgentJobMultiThread_ShouldCleanupStopChildJobs to determine if jobs should be stopped *** 443 | EXEC [dbo].AgentJobMultiThread_ShouldCleanupStopChildJobs 444 | @workload_identifier = @workload_identifier, 445 | @parent_start_time = @parent_start_time, 446 | @max_minutes_to_run = @max_minutes_to_run, 447 | @should_stop_jobs_OUT = @stop_jobs OUTPUT; 448 | 449 | 450 | 451 | -- *** STEP 3: call AgentJobMultiThread_FinalizeCleanup to reschedule job if cleanup can't happen yet *** 452 | IF @stop_jobs = 0 453 | BEGIN 454 | EXEC [dbo].AgentJobMultiThread_FinalizeCleanup 455 | @workload_identifier = @workload_identifier, 456 | @retry_cleanup = 1; 457 | 458 | RETURN; 459 | END; 460 | 461 | 462 | -- *** STEP 4: call AgentJobMultiThread_CleanupChildJobs to clean up jobs *** 463 | EXEC [dbo].AgentJobMultiThread_CleanupChildJobs 464 | @workload_identifier = @workload_identifier, 465 | @child_job_error_count_OUT = @error_count_from_cleanup OUTPUT, 466 | @cleanup_error_message_OUT = @error_message_from_cleanup OUTPUT; 467 | 468 | 469 | 470 | -- *** STEP 5: do any other necessary work in the procedure, such as updating a summary table *** 471 | -- update summary table 472 | UPDATE summary 473 | SET Summary_End_Time_UTC = SYSUTCDATETIME() 474 | , Total_Checksums = log_results.Total_Checksums 475 | , Maximum_Checksum_Value = log_results.Maximum_Checksum_Value 476 | , Approximate_Error_Count = log_results.Child_Error_Count + @error_count_from_cleanup 477 | , Cleanup_Error_Text = @error_message_from_cleanup 478 | FROM [dbo].ThreadingDemo_Summary summary 479 | CROSS JOIN 480 | ( 481 | SELECT 482 | SUM(1.0 * l.Checksum_Count) Total_Checksums 483 | , MAX(l.Maximum_Checksum_Value) Maximum_Checksum_Value 484 | , COUNT_BIG(l.Error_Text) Child_Error_Count 485 | FROM [dbo].ThreadingDemo_Child_Log l 486 | WHERE l.Summary_Start_Time_UTC = @parent_start_time 487 | ) log_results 488 | WHERE summary.Summary_Start_Time_UTC = @parent_start_time; 489 | 490 | 491 | -- purge rows from permanent tables older than 100 days 492 | DELETE FROM [dbo].ThreadingDemo_Summary 493 | WITH (TABLOCK) 494 | WHERE Summary_Start_Time_UTC < DATEADD(DAY, -100, SYSUTCDATETIME()); 495 | 496 | 497 | 498 | -- *** STEP 6: call AgentJobMultiThread_FinalizeCleanup to clean up unnecessary jobs and schedules *** 499 | EXEC [dbo].AgentJobMultiThread_FinalizeCleanup 500 | @workload_identifier = @workload_identifier, 501 | @retry_cleanup = 0; 502 | 503 | RETURN; 504 | END; 505 | 506 | GO 507 | --------------------------------------------------------------------------------