diff --git a/PMDB.Create_Database_Backup.sql b/PMDB.Create_Database_Backup.sql index abbee4f..75f48d3 100644 --- a/PMDB.Create_Database_Backup.sql +++ b/PMDB.Create_Database_Backup.sql @@ -1,78 +1,98 @@ -/*-------------------------------------------------------------------------------+ -| Purpose: Create a backup of a database -| Example: EXEC admin.Create_Database_Backup 'PMDB1_TEST' -+--------------------------------------------------------------------------------*/ +/*=======================================================================+ +| Purpose : Create a backup of the specified database +| Usage : EXEC admin.Create_Database_Backup @DatabaseName = 'PMDB1_TEST' +| Author : Amit Patel (SQL DBA) +| Date : [Insert Date] +| Notes : Ensure the SQL Server Agent service account has access to +| the backup folder path. Customize the path logic as needed. ++========================================================================*/ +-- SQLCMD mode variables (used if running from SSMS in SQLCMD mode) :setvar _server "Server1" :setvar _user "***username***" :setvar _password "***password***" :setvar _database "master" + +-- Connect to the instance :connect $(_server) -U $(_user) -P $(_password) USE [$(_database)]; GO -CREATE PROCEDURE [admin].[Create_Database_Backup] +IF NOT EXISTS ( + SELECT 1 + FROM sys.schemas + WHERE name = 'admin' +) +BEGIN + EXEC('CREATE SCHEMA admin'); +END +GO + +CREATE OR ALTER PROCEDURE [admin].[Create_Database_Backup] ( -@DatabaseName VARCHAR(50) + @DatabaseName SYSNAME ) -AS +AS BEGIN + SET NOCOUNT ON; -PRINT '=====================================================================' -PRINT 'set the name of the database...' -PRINT '=====================================================================' -DECLARE @SourceDB VARCHAR(50) -SET @SourceDB = @DatabaseName --DB_NAME() + -- Initialize variables + DECLARE + @SourceDB SYSNAME = @DatabaseName, + @BackupUser NVARCHAR(255), + @DateStamp CHAR(20), + @TargetPath NVARCHAR(500), + @BackupFile NVARCHAR(500), + @SQL NVARCHAR(MAX); -PRINT '=====================================================================' -PRINT 'get user name...' -PRINT '=====================================================================' -DECLARE @BackupUser VARCHAR(255) -SET @BackupUser = (substring(suser_sname(),charindex('\',suser_sname())+(1),len(suser_sname())-charindex('\',suser_sname()))) + PRINT '=====================================================================' + PRINT 'Creating database backup for: ' + @SourceDB + PRINT '=====================================================================' -PRINT '=====================================================================' -PRINT 'get current date and time...' -PRINT '=====================================================================' -DECLARE @DateStamp VARCHAR(20) -SET @DateStamp = '_' + CONVERT(VARCHAR(20),GetDate(),112) + '_' + REPLACE(CONVERT(VARCHAR(20),GetDate(),108),':','') + -- Extract backup operator's username + SET @BackupUser = PARSENAME(REPLACE(SUSER_SNAME(), '\', '.'), 1); -PRINT '=====================================================================' -PRINT 'set database backup path...' -PRINT '=====================================================================' -DECLARE @TargetPath VARCHAR(255) --- TO DO: Standardize the backup folder location for all servers -IF @@SERVERNAME = 'Server1' SET @TargetPath = 'C:\Temp\' + -- Generate timestamp + SET @DateStamp = FORMAT(GETDATE(), 'yyyyMMdd_HHmmss'); -PRINT '=====================================================================' -PRINT 'set the backup file name...' -PRINT '=====================================================================' -SET @TargetPath = @TargetPath + @SourceDB + @DateStamp + '_' + @BackupUser + '.bak''' -PRINT @TargetPath + -- Set default backup path based on server name + -- TODO: Standardize across environments + IF @@SERVERNAME = 'Server1' + SET @TargetPath = 'C:\Temp\'; + ELSE + SET @TargetPath = 'C:\Backups\'; -- fallback/default -PRINT '=====================================================================' -PRINT 'backup the database...' -PRINT '=====================================================================' -IF EXISTS(SELECT NAME FROM sys.databases where name = @SourceDB) -BEGIN - DECLARE @BACKUP_SQL VARCHAR(MAX) - SET @BACKUP_SQL = - 'BACKUP DATABASE ' + @SourceDB + ' - TO DISK = ''' + @TargetPath + ' - WITH FORMAT, - MEDIANAME = ''' + @BackupUser + ''', - NAME = ''' + @SourceDB + @DateStamp + '''' + -- Compose full backup file path + SET @BackupFile = CONCAT(@TargetPath, @SourceDB, '_', @DateStamp, '_', @BackupUser, '.bak'); - PRINT @BACKUP_SQL - EXEC (@BACKUP_SQL) -END -PRINT '=====================================================================' -PRINT 'Finished!' -PRINT '=====================================================================' + PRINT 'Backup file path: ' + @BackupFile; -END + -- Verify database existence + IF EXISTS (SELECT 1 FROM sys.databases WHERE name = @SourceDB) + BEGIN + SET @SQL = ' + BACKUP DATABASE [' + @SourceDB + '] + TO DISK = N''' + @BackupFile + ''' + WITH FORMAT, + INIT, + NAME = N''' + @SourceDB + '_Full_Backup_' + @DateStamp + ''', + MEDIANAME = N''' + @BackupUser + ''', + STATS = 10; + '; + PRINT 'Executing backup command...'; + PRINT @SQL; + EXEC (@SQL); + PRINT 'Backup completed successfully.'; + END + ELSE + BEGIN + RAISERROR('Database "%s" does not exist.', 16, 1, @SourceDB); + END + PRINT '=====================================================================' + PRINT 'Backup procedure finished.' + PRINT '=====================================================================' +END GO - -