forked from ktaranov/sqlserver-kit
-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy pathJobs_Find_And_Replace_Text.sql
117 lines (104 loc) · 2.96 KB
/
Jobs_Find_And_Replace_Text.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
/*
<documentation>
<summary>Replace text in jobs</summary>
<returns>No.</returns>
<issues>No</issues>
<author>Max Vernon</author>
<created>2019-04-30</created>
<modified>2019-09-06 by Konstantin Taranov</modified>
<version>1.1</version>
<sourceLink>https://github.com/ktaranov/sqlserver-kit/blob/master/Scripts/Jobs_Find_And_Replace_Text.sql</sourceLink>
<originalLink>https://www.sqlserverscience.com/tools/find-and-replace-sql-server-agent-jobs/</originalLink>
</documentation>
*/
USE msdb;
GO
DECLARE @Find nvarchar(max);
DECLARE @Replace nvarchar(max);
DECLARE @DebugOnly bit;
SET @Find = N'\\SERVERA\Backups';
SET @Replace = N'\\SERVERB\Backups';
SET @DebugOnly = 1;
IF OBJECT_ID(N'tempdb..#excludeJobs', N'U') IS NOT NULL
BEGIN
DROP TABLE #excludeJobs;
END
CREATE TABLE #excludeJobs
(
JobName sysname NOT NULL
PRIMARY KEY CLUSTERED
);
INSERT INTO #excludeJobs (JobName)
VALUES ('The Name of a job you want to skip');
IF OBJECT_ID(N'tempdb..#deets', N'U') IS NOT NULL
DROP TABLE #deets;
CREATE TABLE #deets
(
JobName sysname NOT NULL
, StepName sysname NOT NULL
, OldCommand nvarchar(max) NOT NULL
, NewCommand nvarchar(max) NOT NULL
, PRIMARY KEY (JobName, StepName)
);
DECLARE @JobName sysname;
DECLARE @StepName sysname;
DECLARE @StepID int;
DECLARE @Command nvarchar(max);
DECLARE @NewCommand nvarchar(max);
BEGIN TRY
BEGIN TRANSACTION;
DECLARE cur CURSOR LOCAL FORWARD_ONLY STATIC READ_ONLY
FOR
SELECT sj.name
, sjs.step_name
, sjs.step_id
, sjs.command
FROM dbo.sysjobsteps sjs
INNER JOIN dbo.sysjobs sj ON sjs.job_id = sj.job_id
WHERE sjs.command LIKE N'%' + @Find + N'%' ESCAPE N'|' COLLATE SQL_Latin1_General_CP1_CI_AS
AND sj.enabled = 1
AND NOT EXISTS (
SELECT 1
FROM #excludeJobs ej
WHERE ej.JobName = sj.name
)
ORDER BY sj.name
, sjs.step_name;
OPEN cur;
FETCH NEXT FROM cur INTO @JobName
, @StepName
, @StepID
, @Command;
WHILE @@FETCH_STATUS = 0
BEGIN
SET @NewCommand = REPLACE(@Command, @Find, @Replace) COLLATE SQL_Latin1_General_CP1_CI_AS;
INSERT INTO #deets (JobName, StepName, OldCommand, NewCommand)
SELECT JobName = @JobName
, StepName = @StepName
, PriorCommand = @Command
, NewCommand = @NewCommand;
IF @DebugOnly = 0
BEGIN
EXEC dbo.sp_update_jobstep @job_name = @JobName, @step_id = @StepID, @command = @NewCommand;
PRINT N'Updated ' + @JobName;
END
FETCH NEXT FROM cur INTO @JobName
, @StepName
, @StepID
, @Command;
END
CLOSE cur;
DEALLOCATE cur;
SELECT *
FROM #deets;
COMMIT TRANSACTION;
END TRY
BEGIN CATCH
IF @@TRANCOUNT > 0
BEGIN
ROLLBACK TRANSACTION;
PRINT N'Transaction rolled back';
END
PRINT ERROR_MESSAGE();
PRINT ERROR_LINE();
END CATCH