-
-
Notifications
You must be signed in to change notification settings - Fork 98
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Обновлена служебная база мониторинга и сопровождения
- Обновлена документация - Добавлена процедура формирования бэкапов - Добавлена процедура очистки файлов - Обновлены миграции и скрипты создания базы
- Loading branch information
Showing
4 changed files
with
507 additions
and
1 deletion.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
127 changes: 127 additions & 0 deletions
127
...Server-Maintenance/Service-Database/Migrations/V1_0_0_8__Backup_AddProcBackupDatabase.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,127 @@ | ||
CREATE PROCEDURE [dbo].[sp_BackupDatabase] | ||
@databaseName sysname, | ||
@backupDirectory nvarchar(max), | ||
@backupType nvarchar(10) = 'FULL', | ||
@useSubdirectory bit = 1, | ||
@showScriptOnly bit = 0, | ||
@backupCompressionType nvarchar(10) = 'AUTO', | ||
@copyOnly bit = 0, | ||
@checksum bit = 0, | ||
@continiueOnError bit = 0, | ||
@blockSize int = 0, | ||
@maxTransferSize int = 0, | ||
@bufferCount int = 0, | ||
@verify bit = 0 | ||
|
||
AS | ||
BEGIN | ||
SET NOCOUNT ON; | ||
|
||
DECLARE | ||
@backupExtension nvarchar(5), | ||
@fileName nvarchar(max), | ||
@backupFileFullName nvarchar(max), | ||
@useCompression bit, | ||
@msg nvarchar(max), | ||
@sql nvarchar(max); | ||
|
||
IF DB_ID(@databaseName) IS NULL | ||
BEGIN | ||
SET @msg = 'Database ' + @databaseName + ' is not exists.'; | ||
THROW 51000, @msg, 1; | ||
RETURN -1; | ||
END | ||
|
||
IF(NOT UPPER(@backupType) IN ('FULL', 'DIFF', 'TRN')) | ||
BEGIN | ||
SET @msg = 'Backup type is incorrect. Valid values: FULL, DIFF, TRN.'; | ||
THROW 51000, @msg, 1; | ||
RETURN -1; | ||
END | ||
|
||
IF(NOT UPPER(@backupCompressionType) IN ('AUTO', 'ENABLE', 'DISABLE')) | ||
BEGIN | ||
SET @msg = 'Backup compression type is incorrect. Valid values: AUTO, ENABLE, DISABLE.'; | ||
THROW 51000, @msg, 1; | ||
RETURN -1; | ||
END | ||
|
||
SET @backupExtension = | ||
CASE | ||
WHEN @backupType = 'FULL' THEN 'bak' | ||
WHEN @backupType = 'DIFF' THEN 'diff' | ||
WHEN @backupType = 'TRN' THEN 'trn' | ||
END | ||
|
||
if(@backupCompressionType = 'AUTO') | ||
BEGIN | ||
SELECT @useCompression = CAST(value AS bit) | ||
FROM sys.configurations | ||
WHERE name = 'backup compression default'; | ||
END ELSE IF(@backupCompressionType = 'ENABLE') | ||
BEGIN | ||
SET @useCompression = 1 | ||
END ELSE IF(@backupCompressionType = 'DISABLE') | ||
BEGIN | ||
SET @useCompression = 0 | ||
END | ||
|
||
SET @fileName = @databaseName + '_backup_' + FORMAT(sysdatetime(), 'yyyy_MM_dd_HHmmss_ffffff'); | ||
|
||
SET @backupFileFullName = | ||
CASE WHEN SUBSTRING(@backupDirectory, LEN(@backupDirectory), 1) = '\' THEN SUBSTRING(@backupDirectory, 1, LEN(@backupDirectory) - 1) ELSE @backupDirectory END + | ||
'\' + | ||
CASE WHEN @useSubdirectory = 1 THEN @databaseName + '\' ELSE '' END; | ||
|
||
if(@showScriptOnly = 0) | ||
BEGIN | ||
SET @sql = 'EXEC master.sys.xp_create_subdir N''' + @backupFileFullName + '''' | ||
EXECUTE sp_executesql @sql | ||
END | ||
|
||
SET @backupFileFullName = @backupFileFullName + @fileName + '.' + @backupExtension; | ||
|
||
SET @sql = | ||
'BACKUP ' + CASE WHEN @backupType = 'TRN' THEN 'LOG' ELSE 'DATABASE' END + ' [' + @databaseName + '] | ||
TO DISK = N''' + @backupFileFullName + ''' WITH NOFORMAT, | ||
NOINIT, | ||
NAME = N''' + @fileName + ''', | ||
SKIP, REWIND, NOUNLOAD' + | ||
CASE WHEN @backupType = 'DIFF' THEN ', DIFFERENTIAL' ELSE '' END + | ||
CASE WHEN @useCompression = 1 THEN ', COMPRESSION' ELSE '' END + | ||
CASE WHEN @copyOnly = 1 THEN ', COPY_ONLY' ELSE '' END + | ||
CASE WHEN @checksum = 1 THEN ', CHECKSUM' ELSE '' END + | ||
CASE WHEN @continiueOnError = 1 THEN ', CONTINUE_AFTER_ERROR' ELSE '' END + | ||
CASE WHEN @blockSize > 0 THEN ', BLOCKSIZE = ' + CAST(@blockSize as nvarchar(max)) ELSE '' END + | ||
CASE WHEN @maxTransferSize > 0 THEN ', MAXTRANSFERSIZE = ' + CAST(@maxTransferSize as nvarchar(max)) ELSE '' END + | ||
CASE WHEN @bufferCount > 0 THEN ', BUFFERCOUNT = ' + CAST(@bufferCount as nvarchar(max)) ELSE '' END + ', STATS = 10;' | ||
|
||
if(@verify = 1) | ||
BEGIN | ||
DECLARE @backupSetId as int; | ||
|
||
SELECT @backupSetId = position from msdb..backupset | ||
WHERE [database_name] = @databaseName and backup_set_id = ( | ||
select max(backup_set_id) | ||
from msdb..backupset | ||
where [database_name] = @databaseName | ||
) | ||
|
||
IF @backupSetId is null AND @showScriptOnly = 0 | ||
BEGIN | ||
raiserror(N'Ошибка верификации. Сведения о резервном копировании для базы данных не найдены.', 16, 1) | ||
END | ||
|
||
SET @sql = @sql + ' | ||
RESTORE VERIFYONLY FROM DISK = N''' + @backupFileFullName + ''' WITH FILE = ' + CAST(@backupSetId AS nvarchar(max)) + ', NOUNLOAD, NOREWIND;' | ||
END | ||
|
||
if(@showScriptOnly = 1) | ||
BEGIN | ||
PRINT @sql | ||
END ELSE | ||
BEGIN | ||
EXECUTE sp_executesql @sql | ||
END | ||
END |
47 changes: 47 additions & 0 deletions
47
SQL-Server-Maintenance/Service-Database/Migrations/V1_0_0_9__Backup_AddProcClearFiles.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,47 @@ | ||
CREATE PROCEDURE [dbo].[sp_ClearFiles] | ||
@folderPath nvarchar(max), | ||
@fileType bit = 0, | ||
@fileExtension nvarchar(10) = null, | ||
@cutoffDate datetime = null, | ||
@cutoffDateDays int = null, | ||
@includeSubfolders bit = 1, | ||
@scriptOnly bit = 0 | ||
AS | ||
BEGIN | ||
SET NOCOUNT ON; | ||
|
||
DECLARE @msg nvarchar(max); | ||
|
||
IF(@cutoffDate is not null AND @cutoffDateDays is not null) | ||
BEGIN | ||
SET @msg = 'You should setup only one parameter: @cutoffDate or @cutoffDateDays'; | ||
THROW 51000, @msg, 1; | ||
RETURN -1; | ||
END | ||
|
||
IF(@cutoffDateDays IS NOT NULL) | ||
BEGIN | ||
SET @cutoffDate = DATEADD(day, -@cutoffDateDays, GETDATE()) | ||
END ELSE IF(@cutoffDate is null) | ||
BEGIN | ||
SET @cutoffDate = GETDATE() | ||
END | ||
|
||
DECLARE @sql nvarchar(max); | ||
SET @sql = 'EXECUTE master.dbo.xp_delete_file ' + | ||
CAST(@fileType AS nvarchar(max)) + | ||
',N''' + @folderPath + '''' + | ||
',N''' + @fileExtension + | ||
''',N''' + FORMAT(@cutoffDate, 'yyyy-MM-ddTHH:mm:ss') + ''',' + | ||
CAST(@includeSubfolders AS nvarchar(max)) | ||
|
||
IF(@scriptOnly = 1) | ||
BEGIN | ||
PRINT @sql | ||
END ELSE | ||
BEGIN | ||
EXECUTE sp_executesql @sql | ||
END | ||
END | ||
|
||
|
Oops, something went wrong.