forked from BrentOzarULTD/SQL-Server-First-Responder-Kit
-
Notifications
You must be signed in to change notification settings - Fork 0
/
sp_AllNightLog_Setup.sql
1323 lines (818 loc) · 41.8 KB
/
sp_AllNightLog_Setup.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
SET ANSI_NULLS ON;
SET ANSI_PADDING ON;
SET ANSI_WARNINGS ON;
SET ARITHABORT ON;
SET CONCAT_NULL_YIELDS_NULL ON;
SET QUOTED_IDENTIFIER ON;
SET STATISTICS IO OFF;
SET STATISTICS TIME OFF;
GO
IF OBJECT_ID('dbo.sp_AllNightLog_Setup') IS NULL
EXEC ('CREATE PROCEDURE dbo.sp_AllNightLog_Setup AS RETURN 0;');
GO
ALTER PROCEDURE dbo.sp_AllNightLog_Setup
@RPOSeconds BIGINT = 30,
@RTOSeconds BIGINT = 30,
@BackupPath NVARCHAR(MAX) = NULL,
@RestorePath NVARCHAR(MAX) = NULL,
@Jobs TINYINT = 10,
@RunSetup BIT = 0,
@UpdateSetup BIT = 0,
@EnableBackupJobs INT = NULL,
@EnableRestoreJobs INT = NULL,
@Debug BIT = 0,
@FirstFullBackup BIT = 0,
@FirstDiffBackup BIT = 0,
@Help BIT = 0,
@Version VARCHAR(30) = NULL OUTPUT,
@VersionDate DATETIME = NULL OUTPUT,
@VersionCheckMode BIT = 0
WITH RECOMPILE
AS
SET NOCOUNT ON;
BEGIN;
SELECT @Version = '3.96', @VersionDate = '20200712';
IF(@VersionCheckMode = 1)
BEGIN
RETURN;
END;
IF @Help = 1
BEGIN
PRINT '
/*
sp_AllNightLog_Setup from http://FirstResponderKit.org
This script sets up a database, tables, rows, and jobs for sp_AllNightLog, including:
* Creates a database
* Right now it''s hard-coded to use msdbCentral, that might change later
* Creates tables in that database!
* dbo.backup_configuration
* Hold variables used by stored proc to make runtime decisions
* RPO: Seconds, how often we look for databases that need log backups
* Backup Path: The path we feed to Ola H''s backup proc
* dbo.backup_worker
* Holds list of databases and some information that helps our Agent jobs figure out if they need to take another log backup
* Creates tables in msdb
* dbo.restore_configuration
* Holds variables used by stored proc to make runtime decisions
* RTO: Seconds, how often to look for log backups to restore
* Restore Path: The path we feed to sp_DatabaseRestore
* dbo.restore_worker
* Holds list of databases and some information that helps our Agent jobs figure out if they need to look for files to restore
* Creates agent jobs
* 1 job that polls sys.databases for new entries
* 10 jobs that run to take log backups
* Based on a queue table
* Requires Ola Hallengren''s Database Backup stored proc
To learn more, visit http://FirstResponderKit.org where you can download new
versions for free, watch training videos on how it works, get more info on
the findings, contribute your own code, and more.
Known limitations of this version:
- Only Microsoft-supported versions of SQL Server. Sorry, 2005 and 2000! And really, maybe not even anything less than 2016. Heh.
- The repository database name is hard-coded to msdbCentral.
Unknown limitations of this version:
- None. (If we knew them, they would be known. Duh.)
Changes - for the full list of improvements and fixes in this version, see:
https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/
Parameter explanations:
@RunSetup BIT, defaults to 0. When this is set to 1, it will run the setup portion to create database, tables, and worker jobs.
@UpdateSetup BIT, defaults to 0. When set to 1, will update existing configs for RPO/RTO and database backup/restore paths.
@RPOSeconds BIGINT, defaults to 30. Value in seconds you want to use to determine if a new log backup needs to be taken.
@BackupPath NVARCHAR(MAX), defaults to = ''D:\Backup''. You 99.99999% will need to change this path to something else. This tells Ola''s job where to put backups.
@Debug BIT, defaults to 0. Whent this is set to 1, it prints out dynamic SQL commands
Sample call:
EXEC dbo.sp_AllNightLog_Setup
@RunSetup = 1,
@RPOSeconds = 30,
@BackupPath = N''M:\MSSQL\Backup'',
@Debug = 1
For more documentation: https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/
MIT License
Copyright (c) 2020 Brent Ozar Unlimited
Permission is hereby granted, free of charge, to any person obtaining a copy
of this software and associated documentation files (the "Software"), to deal
in the Software without restriction, including without limitation the rights
to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
copies of the Software, and to permit persons to whom the Software is
furnished to do so, subject to the following conditions:
The above copyright notice and this permission notice shall be included in all
copies or substantial portions of the Software.
THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE
SOFTWARE.
*/';
RETURN;
END; /* IF @Help = 1 */
DECLARE @database NVARCHAR(128) = NULL; --Holds the database that's currently being processed
DECLARE @error_number INT = NULL; --Used for TRY/CATCH
DECLARE @error_severity INT; --Used for TRY/CATCH
DECLARE @error_state INT; --Used for TRY/CATCH
DECLARE @msg NVARCHAR(4000) = N''; --Used for RAISERROR
DECLARE @rpo INT; --Used to hold the RPO value in our configuration table
DECLARE @backup_path NVARCHAR(MAX); --Used to hold the backup path in our configuration table
DECLARE @db_sql NVARCHAR(MAX) = N''; --Used to hold the dynamic SQL to create msdbCentral
DECLARE @tbl_sql NVARCHAR(MAX) = N''; --Used to hold the dynamic SQL that creates tables in msdbCentral
DECLARE @database_name NVARCHAR(256) = N'msdbCentral'; --Used to hold the name of the database we create to centralize data
--Right now it's hardcoded to msdbCentral, but I made it dynamic in case that changes down the line
/*These variables control the loop to create/modify jobs*/
DECLARE @job_sql NVARCHAR(MAX) = N''; --Used to hold the dynamic SQL that creates Agent jobs
DECLARE @counter INT = 0; --For looping to create 10 Agent jobs
DECLARE @job_category NVARCHAR(MAX) = N'''Database Maintenance'''; --Job category
DECLARE @job_owner NVARCHAR(128) = QUOTENAME(SUSER_SNAME(0x01), ''''); -- Admin user/owner
DECLARE @jobs_to_change TABLE(name SYSNAME); -- list of jobs we need to enable or disable
DECLARE @current_job_name SYSNAME; -- While looping through Agent jobs to enable or disable
DECLARE @active_start_date INT = (CONVERT(INT, CONVERT(VARCHAR(10), GETDATE(), 112)));
DECLARE @started_waiting_for_jobs DATETIME; --We need to wait for a while when disabling jobs
/*Specifically for Backups*/
DECLARE @job_name_backups NVARCHAR(MAX) = N'''sp_AllNightLog_Backup_Job_'''; --Name of log backup job
DECLARE @job_description_backups NVARCHAR(MAX) = N'''This is a worker for the purposes of taking log backups from msdbCentral.dbo.backup_worker queue table.'''; --Job description
DECLARE @job_command_backups NVARCHAR(MAX) = N'''EXEC sp_AllNightLog @Backup = 1'''; --Command the Agent job will run
/*Specifically for Restores*/
DECLARE @job_name_restores NVARCHAR(MAX) = N'''sp_AllNightLog_Restore_Job_'''; --Name of log backup job
DECLARE @job_description_restores NVARCHAR(MAX) = N'''This is a worker for the purposes of restoring log backups from msdb.dbo.restore_worker queue table.'''; --Job description
DECLARE @job_command_restores NVARCHAR(MAX) = N'''EXEC sp_AllNightLog @Restore = 1'''; --Command the Agent job will run
/*
Sanity check some variables
*/
IF ((@RunSetup = 0 OR @RunSetup IS NULL) AND (@UpdateSetup = 0 OR @UpdateSetup IS NULL))
BEGIN
RAISERROR('You have to either run setup or update setup. You can''t not do neither nor, if you follow. Or not.', 0, 1) WITH NOWAIT;
RETURN;
END;
/*
Should be a positive number
*/
IF (@RPOSeconds < 0)
BEGIN
RAISERROR('Please choose a positive number for @RPOSeconds', 0, 1) WITH NOWAIT;
RETURN;
END;
/*
Probably shouldn't be more than 20
*/
IF (@Jobs > 20) OR (@Jobs < 1)
BEGIN
RAISERROR('We advise sticking with 1-20 jobs.', 0, 1) WITH NOWAIT;
RETURN;
END;
/*
Probably shouldn't be more than 4 hours
*/
IF (@RPOSeconds >= 14400)
BEGIN
RAISERROR('If your RPO is really 4 hours, perhaps you''d be interested in a more modest recovery model, like SIMPLE?', 0, 1) WITH NOWAIT;
RETURN;
END;
/*
Can't enable both the backup and restore jobs at the same time
*/
IF @EnableBackupJobs = 1 AND @EnableRestoreJobs = 1
BEGIN
RAISERROR('You are not allowed to enable both the backup and restore jobs at the same time. Pick one, bucko.', 0, 1) WITH NOWAIT;
RETURN;
END;
/*
Make sure xp_cmdshell is enabled
*/
IF NOT EXISTS (SELECT * FROM sys.configurations WHERE name = 'xp_cmdshell' AND value_in_use = 1)
BEGIN
RAISERROR('xp_cmdshell must be enabled so we can get directory contents to check for new databases to restore.', 0, 1) WITH NOWAIT
RETURN;
END
/*
Make sure Ola Hallengren's scripts are installed in master
*/
IF 2 <> (SELECT COUNT(*) FROM master.sys.procedures WHERE name IN('CommandExecute', 'DatabaseBackup'))
BEGIN
RAISERROR('Ola Hallengren''s CommandExecute and DatabaseBackup must be installed in the master database. More info: http://ola.hallengren.com', 0, 1) WITH NOWAIT
RETURN;
END
/*
Make sure sp_DatabaseRestore is installed in master
*/
IF NOT EXISTS (SELECT * FROM master.sys.procedures WHERE name = 'sp_DatabaseRestore')
BEGIN
RAISERROR('sp_DatabaseRestore must be installed in master. To get it: http://FirstResponderKit.org', 0, 1) WITH NOWAIT
RETURN;
END
/*
Basic path sanity checks
*/
IF (@BackupPath NOT LIKE '[c-zC-Z]:\%') --Local path, don't think anyone has A or B drives
AND (@BackupPath NOT LIKE '\\[a-zA-Z0-9]%\%') --UNC path
BEGIN
RAISERROR('Are you sure that''s a real path?', 0, 1) WITH NOWAIT;
RETURN;
END;
/*
If you want to update the table, one of these has to not be NULL
*/
IF @UpdateSetup = 1
AND ( @RPOSeconds IS NULL
AND @BackupPath IS NULL
AND @RPOSeconds IS NULL
AND @RestorePath IS NULL
AND @EnableBackupJobs IS NULL
AND @EnableRestoreJobs IS NULL
)
BEGIN
RAISERROR('If you want to update configuration settings, they can''t be NULL. Please Make sure @RPOSeconds / @RTOSeconds or @BackupPath / @RestorePath has a value', 0, 1) WITH NOWAIT;
RETURN;
END;
IF @UpdateSetup = 1
GOTO UpdateConfigs;
IF @RunSetup = 1
BEGIN
BEGIN TRY
BEGIN
/*
First check to see if Agent is running -- we'll get errors if it's not
*/
IF ( SELECT 1
FROM sys.all_objects
WHERE name = 'dm_server_services' ) IS NOT NULL
BEGIN
IF EXISTS (
SELECT 1
FROM sys.dm_server_services
WHERE servicename LIKE 'SQL Server Agent%'
AND status_desc = 'Stopped'
)
BEGIN
RAISERROR('SQL Server Agent is not currently running -- it needs to be enabled to add backup worker jobs and the new database polling job', 0, 1) WITH NOWAIT;
RETURN;
END;
END
BEGIN
/*
Check to see if the database exists
*/
RAISERROR('Checking for msdbCentral', 0, 1) WITH NOWAIT;
SET @db_sql += N'
IF DATABASEPROPERTYEX(' + QUOTENAME(@database_name, '''') + ', ''Status'') IS NULL
BEGIN
RAISERROR(''Creating msdbCentral'', 0, 1) WITH NOWAIT;
CREATE DATABASE ' + QUOTENAME(@database_name) + ';
ALTER DATABASE ' + QUOTENAME(@database_name) + ' SET RECOVERY FULL;
END
';
IF @Debug = 1
BEGIN
RAISERROR(@db_sql, 0, 1) WITH NOWAIT;
END;
IF @db_sql IS NULL
BEGIN
RAISERROR('@db_sql is NULL for some reason', 0, 1) WITH NOWAIT;
END;
EXEC sp_executesql @db_sql;
/*
Check for tables and stuff
*/
RAISERROR('Checking for tables in msdbCentral', 0, 1) WITH NOWAIT;
SET @tbl_sql += N'
USE ' + QUOTENAME(@database_name) + '
IF OBJECT_ID(''' + QUOTENAME(@database_name) + '.dbo.backup_configuration'') IS NULL
BEGIN
RAISERROR(''Creating table dbo.backup_configuration'', 0, 1) WITH NOWAIT;
CREATE TABLE dbo.backup_configuration (
database_name NVARCHAR(256),
configuration_name NVARCHAR(512),
configuration_description NVARCHAR(512),
configuration_setting NVARCHAR(MAX)
);
END
ELSE
BEGIN
RAISERROR(''Backup configuration table exists, truncating'', 0, 1) WITH NOWAIT;
TRUNCATE TABLE dbo.backup_configuration
END
RAISERROR(''Inserting configuration values'', 0, 1) WITH NOWAIT;
INSERT dbo.backup_configuration (database_name, configuration_name, configuration_description, configuration_setting)
VALUES (''all'', ''log backup frequency'', ''The length of time in second between Log Backups.'', ''' + CONVERT(NVARCHAR(10), @RPOSeconds) + ''');
INSERT dbo.backup_configuration (database_name, configuration_name, configuration_description, configuration_setting)
VALUES (''all'', ''log backup path'', ''The path to which Log Backups should go.'', ''' + @BackupPath + ''');
INSERT dbo.backup_configuration (database_name, configuration_name, configuration_description, configuration_setting)
VALUES (''all'', ''change backup type'', ''For Ola Hallengren DatabaseBackup @ChangeBackupType param: Y = escalate to fulls, MSDB = escalate by checking msdb backup history.'', ''MSDB'');
INSERT dbo.backup_configuration (database_name, configuration_name, configuration_description, configuration_setting)
VALUES (''all'', ''encrypt'', ''For Ola Hallengren DatabaseBackup: Y = encrypt the backup. N (default) = do not encrypt.'', NULL);
INSERT dbo.backup_configuration (database_name, configuration_name, configuration_description, configuration_setting)
VALUES (''all'', ''encryptionalgorithm'', ''For Ola Hallengren DatabaseBackup: native 2014 choices include TRIPLE_DES_3KEY, AES_128, AES_192, AES_256.'', NULL);
INSERT dbo.backup_configuration (database_name, configuration_name, configuration_description, configuration_setting)
VALUES (''all'', ''servercertificate'', ''For Ola Hallengren DatabaseBackup: server certificate that is used to encrypt the backup.'', NULL);
IF OBJECT_ID(''' + QUOTENAME(@database_name) + '.dbo.backup_worker'') IS NULL
BEGIN
RAISERROR(''Creating table dbo.backup_worker'', 0, 1) WITH NOWAIT;
CREATE TABLE dbo.backup_worker (
id INT IDENTITY(1, 1) PRIMARY KEY CLUSTERED,
database_name NVARCHAR(256),
last_log_backup_start_time DATETIME DEFAULT ''19000101'',
last_log_backup_finish_time DATETIME DEFAULT ''99991231'',
is_started BIT DEFAULT 0,
is_completed BIT DEFAULT 0,
error_number INT DEFAULT NULL,
last_error_date DATETIME DEFAULT NULL,
ignore_database BIT DEFAULT 0,
full_backup_required BIT DEFAULT ' + CASE WHEN @FirstFullBackup = 0 THEN N'0,' ELSE N'1,' END + CHAR(10) +
N'diff_backup_required BIT DEFAULT ' + CASE WHEN @FirstDiffBackup = 0 THEN N'0' ELSE N'1' END + CHAR(10) +
N');
END;
ELSE
BEGIN
RAISERROR(''Backup worker table exists, truncating'', 0, 1) WITH NOWAIT;
TRUNCATE TABLE dbo.backup_worker
END
RAISERROR(''Inserting databases for backups'', 0, 1) WITH NOWAIT;
INSERT ' + QUOTENAME(@database_name) + '.dbo.backup_worker (database_name)
SELECT d.name
FROM sys.databases d
WHERE NOT EXISTS (
SELECT *
FROM msdbCentral.dbo.backup_worker bw
WHERE bw.database_name = d.name
)
AND d.database_id > 4;
';
IF @Debug = 1
BEGIN
SET @msg = SUBSTRING(@tbl_sql, 0, 2044)
RAISERROR(@msg, 0, 1) WITH NOWAIT;
SET @msg = SUBSTRING(@tbl_sql, 2044, 4088)
RAISERROR(@msg, 0, 1) WITH NOWAIT;
SET @msg = SUBSTRING(@tbl_sql, 4088, 6132)
RAISERROR(@msg, 0, 1) WITH NOWAIT;
SET @msg = SUBSTRING(@tbl_sql, 6132, 8176)
RAISERROR(@msg, 0, 1) WITH NOWAIT;
END;
IF @tbl_sql IS NULL
BEGIN
RAISERROR('@tbl_sql is NULL for some reason', 0, 1) WITH NOWAIT;
END;
EXEC sp_executesql @tbl_sql;
/*
This section creates tables for restore workers to work off of
*/
/*
In search of msdb
*/
RAISERROR('Checking for msdb. Yeah, I know...', 0, 1) WITH NOWAIT;
IF DATABASEPROPERTYEX('msdb', 'Status') IS NULL
BEGIN
RAISERROR('YOU HAVE NO MSDB WHY?!', 0, 1) WITH NOWAIT;
RETURN;
END;
/* In search of restore_configuration */
RAISERROR('Checking for Restore Worker tables in msdb', 0, 1) WITH NOWAIT;
IF OBJECT_ID('msdb.dbo.restore_configuration') IS NULL
BEGIN
RAISERROR('Creating restore_configuration table in msdb', 0, 1) WITH NOWAIT;
CREATE TABLE msdb.dbo.restore_configuration (
database_name NVARCHAR(256),
configuration_name NVARCHAR(512),
configuration_description NVARCHAR(512),
configuration_setting NVARCHAR(MAX)
);
END;
ELSE
BEGIN
RAISERROR('Restore configuration table exists, truncating', 0, 1) WITH NOWAIT;
TRUNCATE TABLE msdb.dbo.restore_configuration;
END;
RAISERROR('Inserting configuration values to msdb.dbo.restore_configuration', 0, 1) WITH NOWAIT;
INSERT msdb.dbo.restore_configuration (database_name, configuration_name, configuration_description, configuration_setting)
VALUES ('all', 'log restore frequency', 'The length of time in second between Log Restores.', @RTOSeconds);
INSERT msdb.dbo.restore_configuration (database_name, configuration_name, configuration_description, configuration_setting)
VALUES ('all', 'log restore path', 'The path to which Log Restores come from.', @RestorePath);
IF OBJECT_ID('msdb.dbo.restore_worker') IS NULL
BEGIN
RAISERROR('Creating table msdb.dbo.restore_worker', 0, 1) WITH NOWAIT;
CREATE TABLE msdb.dbo.restore_worker (
id INT IDENTITY(1, 1) PRIMARY KEY CLUSTERED,
database_name NVARCHAR(256),
last_log_restore_start_time DATETIME DEFAULT '19000101',
last_log_restore_finish_time DATETIME DEFAULT '99991231',
is_started BIT DEFAULT 0,
is_completed BIT DEFAULT 0,
error_number INT DEFAULT NULL,
last_error_date DATETIME DEFAULT NULL,
ignore_database BIT DEFAULT 0,
full_backup_required BIT DEFAULT 0,
diff_backup_required BIT DEFAULT 0
);
RAISERROR('Inserting databases for restores', 0, 1) WITH NOWAIT;
INSERT msdb.dbo.restore_worker (database_name)
SELECT d.name
FROM sys.databases d
WHERE NOT EXISTS (
SELECT *
FROM msdb.dbo.restore_worker bw
WHERE bw.database_name = d.name
)
AND d.database_id > 4;
END;
/*
Add Jobs
*/
/*
Look for our ten second schedule -- all jobs use this to restart themselves if they fail
Fun fact: you can add the same schedule name multiple times, so we don't want to just stick it in there
*/
RAISERROR('Checking for ten second schedule', 0, 1) WITH NOWAIT;
IF NOT EXISTS (
SELECT 1
FROM msdb.dbo.sysschedules
WHERE name = 'ten_seconds'
)
BEGIN
RAISERROR('Creating ten second schedule', 0, 1) WITH NOWAIT;
EXEC msdb.dbo.sp_add_schedule @schedule_name= ten_seconds,
@enabled = 1,
@freq_type = 4,
@freq_interval = 1,
@freq_subday_type = 2,
@freq_subday_interval = 10,
@freq_relative_interval = 0,
@freq_recurrence_factor = 0,
@active_start_date = @active_start_date,
@active_end_date = 99991231,
@active_start_time = 0,
@active_end_time = 235959;
END;
/*
Look for Backup Pollster job -- this job sets up our watcher for new databases to back up
*/
RAISERROR('Checking for pollster job', 0, 1) WITH NOWAIT;
IF NOT EXISTS (
SELECT 1
FROM msdb.dbo.sysjobs
WHERE name = 'sp_AllNightLog_PollForNewDatabases'
)
BEGIN
RAISERROR('Creating pollster job', 0, 1) WITH NOWAIT;
IF @EnableBackupJobs = 1
BEGIN
EXEC msdb.dbo.sp_add_job @job_name = sp_AllNightLog_PollForNewDatabases,
@description = 'This is a worker for the purposes of polling sys.databases for new entries to insert to the worker queue table.',
@category_name = 'Database Maintenance',
@owner_login_name = 'sa',
@enabled = 1;
END
ELSE
BEGIN
EXEC msdb.dbo.sp_add_job @job_name = sp_AllNightLog_PollForNewDatabases,
@description = 'This is a worker for the purposes of polling sys.databases for new entries to insert to the worker queue table.',
@category_name = 'Database Maintenance',
@owner_login_name = 'sa',
@enabled = 0;
END
RAISERROR('Adding job step', 0, 1) WITH NOWAIT;
EXEC msdb.dbo.sp_add_jobstep @job_name = sp_AllNightLog_PollForNewDatabases,
@step_name = sp_AllNightLog_PollForNewDatabases,
@subsystem = 'TSQL',
@command = 'EXEC sp_AllNightLog @PollForNewDatabases = 1';
RAISERROR('Adding job server', 0, 1) WITH NOWAIT;
EXEC msdb.dbo.sp_add_jobserver @job_name = sp_AllNightLog_PollForNewDatabases;
RAISERROR('Attaching schedule', 0, 1) WITH NOWAIT;
EXEC msdb.dbo.sp_attach_schedule @job_name = sp_AllNightLog_PollForNewDatabases,
@schedule_name = ten_seconds;
END;
/*
Look for Restore Pollster job -- this job sets up our watcher for new databases to back up
*/
RAISERROR('Checking for restore pollster job', 0, 1) WITH NOWAIT;
IF NOT EXISTS (
SELECT 1
FROM msdb.dbo.sysjobs
WHERE name = 'sp_AllNightLog_PollDiskForNewDatabases'
)
BEGIN
RAISERROR('Creating restore pollster job', 0, 1) WITH NOWAIT;
IF @EnableRestoreJobs = 1
BEGIN
EXEC msdb.dbo.sp_add_job @job_name = sp_AllNightLog_PollDiskForNewDatabases,
@description = 'This is a worker for the purposes of polling your restore path for new entries to insert to the worker queue table.',
@category_name = 'Database Maintenance',
@owner_login_name = 'sa',
@enabled = 1;
END
ELSE
BEGIN
EXEC msdb.dbo.sp_add_job @job_name = sp_AllNightLog_PollDiskForNewDatabases,
@description = 'This is a worker for the purposes of polling your restore path for new entries to insert to the worker queue table.',
@category_name = 'Database Maintenance',
@owner_login_name = 'sa',
@enabled = 0;
END
RAISERROR('Adding restore job step', 0, 1) WITH NOWAIT;
EXEC msdb.dbo.sp_add_jobstep @job_name = sp_AllNightLog_PollDiskForNewDatabases,
@step_name = sp_AllNightLog_PollDiskForNewDatabases,
@subsystem = 'TSQL',
@command = 'EXEC sp_AllNightLog @PollDiskForNewDatabases = 1';
RAISERROR('Adding restore job server', 0, 1) WITH NOWAIT;
EXEC msdb.dbo.sp_add_jobserver @job_name = sp_AllNightLog_PollDiskForNewDatabases;
RAISERROR('Attaching schedule', 0, 1) WITH NOWAIT;
EXEC msdb.dbo.sp_attach_schedule @job_name = sp_AllNightLog_PollDiskForNewDatabases,
@schedule_name = ten_seconds;
END;
/*
This section creates @Jobs (quantity) of worker jobs to take log backups with
They work in a queue
It's queuete
*/
RAISERROR('Checking for sp_AllNightLog backup jobs', 0, 1) WITH NOWAIT;
SELECT @counter = COUNT(*) + 1
FROM msdb.dbo.sysjobs
WHERE name LIKE 'sp[_]AllNightLog[_]Backup[_]%';
SET @msg = 'Found ' + CONVERT(NVARCHAR(10), (@counter - 1)) + ' backup jobs -- ' + CASE WHEN @counter < @Jobs THEN + 'starting loop!'
WHEN @counter >= @Jobs THEN 'skipping loop!'
ELSE 'Oh woah something weird happened!'
END;
RAISERROR(@msg, 0, 1) WITH NOWAIT;
WHILE @counter <= @Jobs
BEGIN
RAISERROR('Setting job name', 0, 1) WITH NOWAIT;
SET @job_name_backups = N'sp_AllNightLog_Backup_' + CASE WHEN @counter < 10 THEN N'0' + CONVERT(NVARCHAR(10), @counter)
WHEN @counter >= 10 THEN CONVERT(NVARCHAR(10), @counter)
END;
RAISERROR('Setting @job_sql', 0, 1) WITH NOWAIT;
SET @job_sql = N'
EXEC msdb.dbo.sp_add_job @job_name = ' + @job_name_backups + ',
@description = ' + @job_description_backups + ',
@category_name = ' + @job_category + ',
@owner_login_name = ' + @job_owner + ',';
IF @EnableBackupJobs = 1
BEGIN
SET @job_sql = @job_sql + ' @enabled = 1; ';
END
ELSE
BEGIN
SET @job_sql = @job_sql + ' @enabled = 0; ';
END
SET @job_sql = @job_sql + '
EXEC msdb.dbo.sp_add_jobstep @job_name = ' + @job_name_backups + ',
@step_name = ' + @job_name_backups + ',
@subsystem = ''TSQL'',
@command = ' + @job_command_backups + ';
EXEC msdb.dbo.sp_add_jobserver @job_name = ' + @job_name_backups + ';
EXEC msdb.dbo.sp_attach_schedule @job_name = ' + @job_name_backups + ',
@schedule_name = ten_seconds;
';
SET @counter += 1;
IF @Debug = 1
BEGIN
RAISERROR(@job_sql, 0, 1) WITH NOWAIT;
END;
IF @job_sql IS NULL
BEGIN
RAISERROR('@job_sql is NULL for some reason', 0, 1) WITH NOWAIT;
END;
EXEC sp_executesql @job_sql;
END;
/*
This section creates @Jobs (quantity) of worker jobs to restore logs with
They too work in a queue
Like a queue-t 3.14
*/
RAISERROR('Checking for sp_AllNightLog Restore jobs', 0, 1) WITH NOWAIT;
SELECT @counter = COUNT(*) + 1
FROM msdb.dbo.sysjobs
WHERE name LIKE 'sp[_]AllNightLog[_]Restore[_]%';
SET @msg = 'Found ' + CONVERT(NVARCHAR(10), (@counter - 1)) + ' restore jobs -- ' + CASE WHEN @counter < @Jobs THEN + 'starting loop!'
WHEN @counter >= @Jobs THEN 'skipping loop!'
ELSE 'Oh woah something weird happened!'
END;
RAISERROR(@msg, 0, 1) WITH NOWAIT;
WHILE @counter <= @Jobs
BEGIN
RAISERROR('Setting job name', 0, 1) WITH NOWAIT;
SET @job_name_restores = N'sp_AllNightLog_Restore_' + CASE WHEN @counter < 10 THEN N'0' + CONVERT(NVARCHAR(10), @counter)
WHEN @counter >= 10 THEN CONVERT(NVARCHAR(10), @counter)
END;
RAISERROR('Setting @job_sql', 0, 1) WITH NOWAIT;
SET @job_sql = N'
EXEC msdb.dbo.sp_add_job @job_name = ' + @job_name_restores + ',
@description = ' + @job_description_restores + ',
@category_name = ' + @job_category + ',
@owner_login_name = ' + @job_owner + ',';
IF @EnableRestoreJobs = 1
BEGIN
SET @job_sql = @job_sql + ' @enabled = 1; ';
END
ELSE
BEGIN
SET @job_sql = @job_sql + ' @enabled = 0; ';
END
SET @job_sql = @job_sql + '
EXEC msdb.dbo.sp_add_jobstep @job_name = ' + @job_name_restores + ',
@step_name = ' + @job_name_restores + ',
@subsystem = ''TSQL'',
@command = ' + @job_command_restores + ';
EXEC msdb.dbo.sp_add_jobserver @job_name = ' + @job_name_restores + ';