Skip to content

Commit

Permalink
Небольшие исправления механизма создания заданий по шаблонам
Browse files Browse the repository at this point in the history
- Добавлен флаг принудительного пересоздания заданий по шаблонам
- Обновлена документация
- Исправлена ошибки при создании заданий с несколькими шагами. База могла в одном из заданий использоваться некорректная.
- Обновлены миграции и скрипт создания базы с нуля.
  • Loading branch information
YPermitin committed Nov 9, 2023
1 parent 3ed5c12 commit 31cee1b
Show file tree
Hide file tree
Showing 3 changed files with 222 additions and 5 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -283,6 +283,8 @@ INSERT [dbo].[changelog] ([id], [type], [version], [description], [name], [check
GO
INSERT [dbo].[changelog] ([id], [type], [version], [description], [name], [checksum], [installed_by], [installed_on], [success]) VALUES (13, 0, N'1.0.0.11', N'Refactoring (24 ms)', N'V1_0_0_11__Refactoring.sql', N'F32BC5B3DCA7EFEB049F1C7A032C30F3', N'sa', CAST(N'2023-10-31T21:52:07.140' AS DateTime), 1)
GO
INSERT [dbo].[changelog] ([id], [type], [version], [description], [name], [checksum], [installed_by], [installed_on], [success]) VALUES (14, 0, N'1.0.0.12', N'Jobs FixCreateOrUPdateJobsBySettingsProc (72 ms)', N'V1_0_0_12__Jobs_FixCreateOrUPdateJobsBySettingsProc.sql', N'830D32CAB88A1ACC673F515AA8D5B96D', N'sa', CAST(N'2023-11-09T18:58:14.717' AS DateTime), 1)
GO
SET IDENTITY_INSERT [dbo].[changelog] OFF
GO

Expand Down Expand Up @@ -1175,6 +1177,7 @@ END
GO

CREATE PROCEDURE [dbo].[sp_CreateOrUpdateJobsBySettings]
@force bit = 0
AS
BEGIN
SET NOCOUNT ON;
Expand Down Expand Up @@ -1282,7 +1285,7 @@ BEGIN
BEGIN
SET @jobName = REPLACE(@Name, '{DatabaseName}', @currentDatabaseName);
SET @jobDescription = REPLACE(@Description, '{DatabaseName}', @currentDatabaseName);
SET @JobAction = REPLACE(@JobAction, '{DatabaseName}', @currentDatabaseName);
DECLARE @currentJobAction nvarchar(max) = REPLACE(@JobAction, '{DatabaseName}', @currentDatabaseName);

SELECT
@jobAlreadyExists = 1,
Expand All @@ -1293,7 +1296,7 @@ BEGIN

-- Если задание уже существует, но в настройках содержится более новая версия,
-- то удаляем старое задание и создаем заново
IF(@jobAlreadyExists = 1 AND @VersionDate > @currentjobVersionDate)
IF(@jobAlreadyExists = 1 AND (@force = 1 OR @VersionDate > @currentjobVersionDate))
BEGIN
EXEC msdb.dbo.sp_delete_job
@job_id = @currentJobId,
Expand All @@ -1308,7 +1311,7 @@ BEGIN
,@jobDescription = @jobDescription
,@jobEnabled = @Enable
,@databaseName = @currentDatabaseName
,@jobAction = @JobAction
,@jobAction = @currentJobAction
,@scheduleEnabled = @ScheduleEnable
,@scheduleFreqType = @ScheduleFreqType
,@scheduleFreqInterval = @ScheduleFreqInterval
Expand Down Expand Up @@ -1337,7 +1340,7 @@ BEGIN

-- Если задание уже существует, но в настройках содержится более новая версия,
-- то удаляем старое задание и создаем заново
IF(@jobAlreadyExists = 1 AND @VersionDate > @currentjobVersionDate)
IF(@jobAlreadyExists = 1 AND (@force = 1 OR @VersionDate > @currentjobVersionDate))
BEGIN
EXEC msdb.dbo.sp_delete_job
@job_id = @currentJobId,
Expand Down
11 changes: 10 additions & 1 deletion SQL-Server-Maintenance/Service-Database/Doc/Job-Settings.md
Original file line number Diff line number Diff line change
Expand Up @@ -258,11 +258,20 @@ EXECUTE [SQLServerMaintenance].[dbo].[sp_StatisticMaintenance]
Для того, чтобы создать / обновить задания по добавленным настройкам нужно вызывать процедуру **sp_CreateOrUpdateJobsBySettings**.

```sql
EXECUTE [dbo].[sp_CreateOrUpdateJobsBySettings]
EXECUTE [dbo].[sp_CreateOrUpdateJobsBySettings]
```

В целом, ее запуск также можно настроить в задании раз в день или чаще, в зависимости от требований.

По умолчанию задания создаются, если их нет и обновляются при наличии шаблона новой версии. Но можно принудительно обновить задания по текущим шаблонам:

```sql
EXECUTE [dbo].[sp_CreateOrUpdateJobsBySettings]
@force = 1
```

Может понадобиться для восстановления изначального вида уже созданных заданий.

## Контроль таймаута выполнения заданий

Выше в шаблоне задавались настройки таймаута для заданий. Но для конкретных заданий таумаут выполнения задается в таблице **JobTimeouts**, в виде:
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,205 @@
ALTER PROCEDURE [dbo].[sp_CreateOrUpdateJobsBySettings]
@force bit = 0
AS
BEGIN
SET NOCOUNT ON;

-- Поля шаблона
DECLARE
@Id int,
@Enable bit,
@ApplyTemplateQuery nvarchar(max),
@Name nvarchar(250),
@Description nvarchar(512),
@JobAction nvarchar(max),
@ScheduleEnable bit,
@ScheduleFreqType int,
@ScheduleFreqInterval int,
@ScheduleFreqSubdayType int,
@ScheduleFreqSubdayInterval int,
@ScheduleFreqRelativeInterval int,
@ScheduleFreqRecurrenceFactor int,
@ScheduleActiveStartDay int,
@ScheduleActiveEndDay int,
@ScheduleActiveStartTime int,
@ScheduleActiveEndTime int,
@VersionDate datetime,
@TimeoutSec int;

DECLARE
@jobName nvarchar(250),
@jobDescription nvarchar(513),
@jobScript nvarchar(max),
@currentjobVersionDate datetime,
@currentJobId uniqueidentifier,
@JobAlreadyExists bit = 0;

-- Служебные переменные
DECLARE
@sql nvarchar(max),
@currentDatabaseName nvarchar(250);

DECLARE job_templates_cursor CURSOR
FOR SELECT
[Id]
,[Enable]
,[ApplyTemplateQuery]
,[Name]
,[Description]
,[JobAction]
,[ScheduleEnable]
,[ScheduleFreqType]
,[ScheduleFreqInterval]
,[ScheduleFreqSubdayType]
,[ScheduleFreqSubdayInterval]
,[ScheduleFreqRelativeInterval]
,[ScheduleFreqRecurrenceFactor]
,[ScheduleActiveStartDay]
,[ScheduleActiveEndDay]
,[ScheduleActiveStartTime]
,[ScheduleActiveEndTime]
,[VersionDate]
,[TimeoutSec]
FROM [dbo].[JobTemplates]
WHERE [UseSetting] = 1;
OPEN job_templates_cursor;

FETCH NEXT FROM job_templates_cursor
INTO @Id, @Enable, @ApplyTemplateQuery, @Name, @Description, @JobAction, @ScheduleEnable,
@ScheduleFreqType, @ScheduleFreqInterval, @ScheduleFreqSubdayType, @ScheduleFreqSubdayInterval,
@ScheduleFreqRelativeInterval, @ScheduleFreqRecurrenceFactor, @ScheduleActiveStartDay,
@ScheduleActiveEndDay, @ScheduleActiveStartTime, @ScheduleActiveEndTime, @VersionDate, @TimeoutSec;

WHILE @@FETCH_STATUS = 0
BEGIN
SET @Description = @Description + ' (Version date:' + CAST(@VersionDate AS nvarchar(max)) + ')';

IF(@ApplyTemplateQuery IS NOT NULL)
BEGIN
-- Задания создаются по базам данных
IF(NOT EXISTS(SELECT
[name]
FROM sys.dm_exec_describe_first_result_set (@ApplyTemplateQuery, NULL, 0)
WHERE [name] = 'DatabaseName'))
BEGIN
PRINT @Name;
THROW 51000, 'Запрос шаблона не содержит поля DatabaseName.', 1;
END

IF (OBJECT_ID('tempdb..##databasesForJobs') IS NOT NULL)
DROP Table ##databasesForJobs;
IF(1 = 0)
BEGIN
-- !!! Костыль для поддержания корректного поведения редактора SQL кода,
-- иначе ругается на несуществующую глобавльную временную таблицу
CREATE TABLE ##databasesForJobs (DatabaseName nvarchar(255));
END
SET @sql = CAST('SELECT [DatabaseName] INTO ##databasesForJobs FROM (' AS nvarchar(max))
+ CAST(@ApplyTemplateQuery AS nvarchar(max))
+ CAST(') AS T' AS nvarchar(max))
EXEC sp_executesql @sql

DECLARE job_templates_databases_cursor CURSOR
FOR SELECT [DatabaseName] FROM ##databasesForJobs;
OPEN job_templates_databases_cursor;
FETCH NEXT FROM job_templates_databases_cursor INTO @currentDatabaseName;
WHILE @@FETCH_STATUS = 0
BEGIN
SET @jobName = REPLACE(@Name, '{DatabaseName}', @currentDatabaseName);
SET @jobDescription = REPLACE(@Description, '{DatabaseName}', @currentDatabaseName);
DECLARE @currentJobAction nvarchar(max) = REPLACE(@JobAction, '{DatabaseName}', @currentDatabaseName);

SELECT
@jobAlreadyExists = 1,
@currentJobId = sj.job_id,
@currentjobVersionDate = CASE WHEN sj.date_modified > sj.date_created THEN sj.date_modified ELSE sj.date_created END
FROM [msdb].[dbo].[sysjobs] sj
WHERE sj.[name] = @jobName

-- Если задание уже существует, но в настройках содержится более новая версия,
-- то удаляем старое задание и создаем заново
IF(@jobAlreadyExists = 1 AND (@force = 1 OR @VersionDate > @currentjobVersionDate))
BEGIN
EXEC msdb.dbo.sp_delete_job
@job_id = @currentJobId,
@delete_unused_schedule = 1;
SET @jobAlreadyExists = 0;
END

IF(@jobAlreadyExists = 0)
BEGIN
EXECUTE [dbo].[sp_CreateSimpleJob]
@jobName = @jobName
,@jobDescription = @jobDescription
,@jobEnabled = @Enable
,@databaseName = @currentDatabaseName
,@jobAction = @currentJobAction
,@scheduleEnabled = @ScheduleEnable
,@scheduleFreqType = @ScheduleFreqType
,@scheduleFreqInterval = @ScheduleFreqInterval
,@scheduleFreqSubdayType = @ScheduleFreqSubdayType
,@scheduleFreqSubdayInterval = @ScheduleFreqSubdayInterval
,@scheduleFreqRelativeInterval = @ScheduleFreqRelativeInterval
,@scheduleFreqRecurrenceFactor = @ScheduleFreqRecurrenceFactor
,@scheduleActiveStartDate = @ScheduleActiveStartDay
,@scheduleActiveEndDate = @ScheduleActiveEndDay
,@scheduleActiveStartTime = @ScheduleActiveStartTime
,@scheduleActiveEndTime = @ScheduleActiveEndTime
,@jobTimeoutSec = @TimeoutSec
END

FETCH NEXT FROM job_templates_databases_cursor INTO @currentDatabaseName;
END
CLOSE job_templates_databases_cursor;
DEALLOCATE job_templates_databases_cursor;
END ELSE BEGIN
SELECT
@jobAlreadyExists = 1,
@currentJobId = sj.job_id,
@currentjobVersionDate = CASE WHEN sj.date_modified > sj.date_created THEN sj.date_modified ELSE sj.date_created END
FROM [msdb].[dbo].[sysjobs] sj
WHERE sj.[name] = @Name

-- Если задание уже существует, но в настройках содержится более новая версия,
-- то удаляем старое задание и создаем заново
IF(@jobAlreadyExists = 1 AND (@force = 1 OR @VersionDate > @currentjobVersionDate))
BEGIN
EXEC msdb.dbo.sp_delete_job
@job_id = @currentJobId,
@delete_unused_schedule = 1;
SET @jobAlreadyExists = 0;
END

IF(@jobAlreadyExists = 0)
BEGIN
-- Задание создается единое на весь сервер
EXECUTE [dbo].[sp_CreateSimpleJob]
@jobName = @Name
,@jobDescription = @Description
,@jobEnabled = @Enable
,@databaseName = 'SQLServerMaintenance'
,@jobAction = @JobAction
,@scheduleEnabled = @ScheduleEnable
,@scheduleFreqType = @ScheduleFreqType
,@scheduleFreqInterval = @ScheduleFreqInterval
,@scheduleFreqSubdayType = @ScheduleFreqSubdayType
,@scheduleFreqSubdayInterval = @ScheduleFreqSubdayInterval
,@scheduleFreqRelativeInterval = @ScheduleFreqRelativeInterval
,@scheduleFreqRecurrenceFactor = @ScheduleFreqRecurrenceFactor
,@scheduleActiveStartDate = @ScheduleActiveStartDay
,@scheduleActiveEndDate = @ScheduleActiveEndDay
,@scheduleActiveStartTime = @ScheduleActiveStartTime
,@scheduleActiveEndTime = @ScheduleActiveEndTime
,@jobTimeoutSec = @TimeoutSec
END
END

FETCH NEXT FROM job_templates_cursor
INTO @Id, @Enable, @ApplyTemplateQuery, @Name, @Description, @JobAction, @ScheduleEnable,
@ScheduleFreqType, @ScheduleFreqInterval, @ScheduleFreqSubdayType, @ScheduleFreqSubdayInterval,
@ScheduleFreqRelativeInterval, @ScheduleFreqRecurrenceFactor, @ScheduleActiveStartDay,
@ScheduleActiveEndDay, @ScheduleActiveStartTime, @ScheduleActiveEndTime, @VersionDate, @TimeoutSec;
END
CLOSE job_templates_cursor;
DEALLOCATE job_templates_cursor;
END

0 comments on commit 31cee1b

Please sign in to comment.