Skip to content

Commit 24e0fd4

Browse files
committed
Adding Backup/Restore scripts
Adding Backup/Restore scripts
1 parent e3c7959 commit 24e0fd4

14 files changed

+1230
-8
lines changed
-3.5 KB
Binary file not shown.
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,68 @@
1+
/* Created By: AJAY DWIVEDI
2+
Created Date: NOV 25, 2014
3+
Purpose: Script out Take Backups
4+
Total Input: 3
5+
*/
6+
7+
DECLARE @ID TINYINT --DB No
8+
DECLARE @name VARCHAR(50) -- database name
9+
DECLARE @Is_Copy_only TINYINT
10+
DECLARE @path VARCHAR(256) -- path for backup files
11+
DECLARE @fileName VARCHAR(256) -- filename for backup
12+
DECLARE @fileDate VARCHAR(20) -- used for file name
13+
DECLARE @BackupString NVARCHAR(2000);
14+
DECLARE @VerificationString NVARCHAR(2000);
15+
16+
--1) specify database backup directory
17+
SET @path = 'C:\Program Files\Microsoft SQL Server\MSSQL12.MSSQLSERVER\MSSQL\Backup'
18+
19+
--2) Specify (True=1) or (False=0) for COPY_ONLY backup option
20+
SET @Is_Copy_only = 1;
21+
22+
SELECT @fileDate = DATENAME(DAY,GETDATE())+CAST(DATENAME(MONTH,GETDATE()) AS VARCHAR(3))
23+
+DATENAME(YEAR,GETDATE())+'_'+REPLACE(REPLACE(RIGHT(CONVERT(VARCHAR, GETDATE(), 100),7),':',''), ' ','0')
24+
25+
--3) Specify your DB names for backup in case of data migration
26+
DECLARE db_cursor CURSOR FOR
27+
SELECT ROW_NUMBER() OVER (ORDER BY name) as ID, name
28+
FROM master.dbo.sysdatabases
29+
WHERE DATABASEPROPERTYEX(NAME,'status') = 'ONLINE'
30+
--AND name IN ('Pubs') -- Data Migration
31+
AND name NOT IN ('master','model','msdb','tempdb') -- Instance Migration
32+
ORDER BY name
33+
34+
OPEN db_cursor
35+
FETCH NEXT FROM db_cursor INTO @ID, @name;
36+
37+
38+
WHILE @@FETCH_STATUS = 0
39+
BEGIN
40+
41+
SET @BackupString = '
42+
-- '+CAST(@ID AS VARCHAR(2))+') ['+@name+']
43+
EXEC master.sys.xp_create_subdir '''+@path+'\'+@name+''';
44+
GO
45+
BACKUP DATABASE ['+@name+'] TO DISK = '''+@path+'\'+@name+'\'+ @name + '_' + @fileDate + '.BAK''
46+
WITH ';
47+
IF(@Is_Copy_only = 1)
48+
SET @BackupString = @BackupString + 'COPY_ONLY, ';
49+
50+
SET @BackupString = @BackupString + 'STATS = 5 ,CHECKSUM, COMPRESSION;
51+
GO';
52+
53+
SET @VerificationString = '
54+
declare @backupSetId as int
55+
select @backupSetId = position from msdb..backupset where database_name=N'''+@name+''' and backup_set_id=(select max(backup_set_id) from msdb..backupset where database_name=N'''+@name+''' )
56+
if @backupSetId is null begin raiserror(N''Verify failed. Backup information for database '''''+@name+''''' not found.'', 16, 1) end
57+
RESTORE VERIFYONLY FROM DISK = N'''+@path+'\'+@name+'\'+ @name + '_' + @fileDate + '.BAK'' WITH FILE = @backupSetId, NOUNLOAD, NOREWIND
58+
GO
59+
';
60+
61+
PRINT @BackupString;
62+
PRINT @VerificationString;
63+
FETCH NEXT FROM db_cursor INTO @ID, @name;
64+
END
65+
66+
67+
CLOSE db_cursor
68+
DEALLOCATE db_cursor
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,182 @@
1+
DECLARE
2+
@sql VARCHAR(2048)
3+
,@sort INT
4+
5+
DECLARE tmp CURSOR FOR
6+
7+
8+
/*********************************************/
9+
/********* DB CONTEXT STATEMENT *********/
10+
/*********************************************/
11+
SELECT '-- [-- DB CONTEXT --] --' AS [-- SQL STATEMENTS --],
12+
1 AS [-- RESULT ORDER HOLDER --]
13+
UNION
14+
SELECT 'USE' + SPACE(1) + QUOTENAME(DB_NAME()) AS [-- SQL STATEMENTS --],
15+
1 AS [-- RESULT ORDER HOLDER --]
16+
17+
UNION
18+
19+
SELECT '' AS [-- SQL STATEMENTS --],
20+
2 AS [-- RESULT ORDER HOLDER --]
21+
22+
UNION
23+
24+
/*********************************************/
25+
/********* DB USER CREATION *********/
26+
/*********************************************/
27+
28+
SELECT '-- [-- DB USERS --] --' AS [-- SQL STATEMENTS --],
29+
3 AS [-- RESULT ORDER HOLDER --]
30+
UNION
31+
SELECT 'IF NOT EXISTS (SELECT [name] FROM sys.database_principals WHERE [name] = ' + SPACE(1) + '''' + [name] + '''' + ') BEGIN CREATE USER ' + SPACE(1) + QUOTENAME([name]) + ' FOR LOGIN ' + QUOTENAME([name]) + ' WITH DEFAULT_SCHEMA = ' + QUOTENAME([default_schema_name]) + SPACE(1) + 'END; ' AS [-- SQL STATEMENTS --],
32+
4 AS [-- RESULT ORDER HOLDER --]
33+
FROM sys.database_principals AS rm
34+
WHERE [type] IN ('U', 'S', 'G') -- windows users, sql users, windows groups
35+
36+
UNION
37+
38+
/*********************************************/
39+
/********* DB ROLE PERMISSIONS *********/
40+
/*********************************************/
41+
SELECT '-- [-- DB ROLES --] --' AS [-- SQL STATEMENTS --],
42+
5 AS [-- RESULT ORDER HOLDER --]
43+
UNION
44+
SELECT 'EXEC sp_addrolemember @rolename ='
45+
+ SPACE(1) + QUOTENAME(USER_NAME(rm.role_principal_id), '''') + ', @membername =' + SPACE(1) + QUOTENAME(USER_NAME(rm.member_principal_id), '''') AS [-- SQL STATEMENTS --],
46+
6 AS [-- RESULT ORDER HOLDER --]
47+
FROM sys.database_role_members AS rm
48+
WHERE USER_NAME(rm.member_principal_id) IN (
49+
--get user names on the database
50+
SELECT [name]
51+
FROM sys.database_principals
52+
WHERE [principal_id] > 4 -- 0 to 4 are system users/schemas
53+
and [type] IN ('G', 'S', 'U') -- S = SQL user, U = Windows user, G = Windows group
54+
)
55+
--ORDER BY rm.role_principal_id ASC
56+
57+
58+
UNION
59+
60+
SELECT '' AS [-- SQL STATEMENTS --],
61+
7 AS [-- RESULT ORDER HOLDER --]
62+
63+
UNION
64+
65+
/*********************************************/
66+
/********* OBJECT LEVEL PERMISSIONS *********/
67+
/*********************************************/
68+
SELECT '-- [-- OBJECT LEVEL PERMISSIONS --] --' AS [-- SQL STATEMENTS --],
69+
8 AS [-- RESULT ORDER HOLDER --]
70+
UNION
71+
SELECT CASE
72+
WHEN perm.state <> 'W' THEN perm.state_desc
73+
ELSE 'GRANT'
74+
END
75+
+ SPACE(1) + perm.permission_name + SPACE(1) + 'ON ' + QUOTENAME(SCHEMA_NAME(obj.schema_id)) + '.' + QUOTENAME(obj.name) --select, execute, etc on specific objects
76+
+ CASE
77+
WHEN cl.column_id IS NULL THEN SPACE(0)
78+
ELSE '(' + QUOTENAME(cl.name) + ')'
79+
END
80+
+ SPACE(1) + 'TO' + SPACE(1) + QUOTENAME(USER_NAME(usr.principal_id)) COLLATE database_default
81+
+ CASE
82+
WHEN perm.state <> 'W' THEN SPACE(0)
83+
ELSE SPACE(1) + 'WITH GRANT OPTION'
84+
END
85+
AS [-- SQL STATEMENTS --],
86+
9 AS [-- RESULT ORDER HOLDER --]
87+
FROM
88+
sys.database_permissions AS perm
89+
INNER JOIN
90+
sys.objects AS obj
91+
ON perm.major_id = obj.[object_id]
92+
INNER JOIN
93+
sys.database_principals AS usr
94+
ON perm.grantee_principal_id = usr.principal_id
95+
LEFT JOIN
96+
sys.columns AS cl
97+
ON cl.column_id = perm.minor_id AND cl.[object_id] = perm.major_id
98+
--WHERE usr.name = @OldUser
99+
--ORDER BY perm.permission_name ASC, perm.state_desc ASC
100+
101+
102+
103+
UNION
104+
105+
SELECT '' AS [-- SQL STATEMENTS --],
106+
10 AS [-- RESULT ORDER HOLDER --]
107+
108+
UNION
109+
110+
/*********************************************/
111+
/********* DB LEVEL PERMISSIONS *********/
112+
/*********************************************/
113+
SELECT '-- [--DB LEVEL PERMISSIONS --] --' AS [-- SQL STATEMENTS --],
114+
11 AS [-- RESULT ORDER HOLDER --]
115+
UNION
116+
SELECT CASE
117+
WHEN perm.state <> 'W' THEN perm.state_desc --W=Grant With Grant Option
118+
ELSE 'GRANT'
119+
END
120+
+ SPACE(1) + perm.permission_name --CONNECT, etc
121+
+ SPACE(1) + 'TO' + SPACE(1) + '[' + USER_NAME(usr.principal_id) + ']' COLLATE database_default --TO <user name>
122+
+ CASE
123+
WHEN perm.state <> 'W' THEN SPACE(0)
124+
ELSE SPACE(1) + 'WITH GRANT OPTION'
125+
END
126+
AS [-- SQL STATEMENTS --],
127+
12 AS [-- RESULT ORDER HOLDER --]
128+
FROM sys.database_permissions AS perm
129+
INNER JOIN
130+
sys.database_principals AS usr
131+
ON perm.grantee_principal_id = usr.principal_id
132+
--WHERE usr.name = @OldUser
133+
134+
WHERE [perm].[major_id] = 0
135+
AND [usr].[principal_id] > 4 -- 0 to 4 are system users/schemas
136+
AND [usr].[type] IN ('G', 'S', 'U') -- S = SQL user, U = Windows user, G = Windows group
137+
138+
UNION
139+
140+
SELECT '' AS [-- SQL STATEMENTS --],
141+
13 AS [-- RESULT ORDER HOLDER --]
142+
143+
UNION
144+
145+
SELECT '-- [--DB LEVEL SCHEMA PERMISSIONS --] --' AS [-- SQL STATEMENTS --],
146+
14 AS [-- RESULT ORDER HOLDER --]
147+
UNION
148+
SELECT CASE
149+
WHEN perm.state <> 'W' THEN perm.state_desc --W=Grant With Grant Option
150+
ELSE 'GRANT'
151+
END
152+
+ SPACE(1) + perm.permission_name --CONNECT, etc
153+
+ SPACE(1) + 'ON' + SPACE(1) + class_desc + '::' COLLATE database_default --TO <user name>
154+
+ QUOTENAME(SCHEMA_NAME(major_id))
155+
+ SPACE(1) + 'TO' + SPACE(1) + QUOTENAME(USER_NAME(grantee_principal_id)) COLLATE database_default
156+
+ CASE
157+
WHEN perm.state <> 'W' THEN SPACE(0)
158+
ELSE SPACE(1) + 'WITH GRANT OPTION'
159+
END
160+
AS [-- SQL STATEMENTS --],
161+
15 AS [-- RESULT ORDER HOLDER --]
162+
from sys.database_permissions AS perm
163+
inner join sys.schemas s
164+
on perm.major_id = s.schema_id
165+
inner join sys.database_principals dbprin
166+
on perm.grantee_principal_id = dbprin.principal_id
167+
WHERE class = 3 --class 3 = schema
168+
169+
170+
ORDER BY [-- RESULT ORDER HOLDER --]
171+
172+
173+
OPEN tmp
174+
FETCH NEXT FROM tmp INTO @sql, @sort
175+
WHILE @@FETCH_STATUS = 0
176+
BEGIN
177+
PRINT @sql
178+
FETCH NEXT FROM tmp INTO @sql, @sort
179+
END
180+
181+
CLOSE tmp
182+
DEALLOCATE tmp
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,68 @@
1+
/* Created By: AJAY DWIVEDI
2+
Created Date: NOV 25, 2014
3+
Purpose: Script out Take Backups
4+
Total Input: 3
5+
*/
6+
7+
DECLARE @ID TINYINT --DB No
8+
DECLARE @name VARCHAR(50) -- database name
9+
DECLARE @Is_Copy_only TINYINT
10+
DECLARE @path VARCHAR(256) -- path for backup files
11+
DECLARE @fileName VARCHAR(256) -- filename for backup
12+
DECLARE @fileDate VARCHAR(20) -- used for file name
13+
DECLARE @BackupString NVARCHAR(2000);
14+
DECLARE @VerificationString NVARCHAR(2000);
15+
16+
--1) specify database backup directory
17+
SET @path = 'G:\mssqldata\backup\'
18+
19+
--2) Specify (True=1) or (False=0) for COPY_ONLY backup option
20+
SET @Is_Copy_only = 1;
21+
22+
SELECT @fileDate = DATENAME(DAY,GETDATE())+CAST(DATENAME(MONTH,GETDATE()) AS VARCHAR(3))
23+
+DATENAME(YEAR,GETDATE())+'_'+REPLACE(REPLACE(RIGHT(CONVERT(VARCHAR, GETDATE(), 100),7),':',''), ' ','0')
24+
25+
--3) Specify your DB names for backup in case of data migration
26+
DECLARE db_cursor CURSOR FOR
27+
SELECT ROW_NUMBER() OVER (ORDER BY name) as ID, name
28+
FROM master.dbo.sysdatabases
29+
WHERE DATABASEPROPERTYEX(NAME,'status') = 'ONLINE'
30+
AND name IN ('Passport','Passport_ChoiceCable','Passport_Dayscript','Passport_ReportTV','Passport_Rogers') -- Data Migration
31+
--AND name NOT IN ('master','model','msdb','tempdb') -- Instance Migration
32+
ORDER BY name
33+
34+
OPEN db_cursor
35+
FETCH NEXT FROM db_cursor INTO @ID, @name;
36+
37+
38+
WHILE @@FETCH_STATUS = 0
39+
BEGIN
40+
41+
SET @BackupString = '
42+
-- '+CAST(@ID AS VARCHAR(2))+') ['+@name+']
43+
--EXEC master.sys.xp_create_subdir '''+@path+(CASE WHEN CHARINDEX('\',RIGHT(LTRIM(RTRIM(@path)),1))=0 THEN '\' ELSE '' END)+@name+''';
44+
--GO
45+
BACKUP DATABASE ['+@name+'] TO DISK = '''+@path+(CASE WHEN CHARINDEX('\',RIGHT(LTRIM(RTRIM(@path)),1))=0 THEN '\' ELSE '' END)+ @name + '_' + @fileDate + '.BAK''
46+
WITH ';
47+
IF(@Is_Copy_only = 1)
48+
SET @BackupString = @BackupString + 'COPY_ONLY, ';
49+
50+
SET @BackupString = @BackupString + 'STATS = 3 ,CHECKSUM, COMPRESSION;
51+
GO';
52+
53+
SET @VerificationString = '
54+
declare @backupSetId as int
55+
select @backupSetId = position from msdb..backupset where database_name=N'''+@name+''' and backup_set_id=(select max(backup_set_id) from msdb..backupset where database_name=N'''+@name+''' )
56+
if @backupSetId is null begin raiserror(N''Verify failed. Backup information for database '''''+@name+''''' not found.'', 16, 1) end
57+
RESTORE VERIFYONLY FROM DISK = N'''+@path+(CASE WHEN CHARINDEX('\',RIGHT(LTRIM(RTRIM(@path)),1))=0 THEN '\' ELSE '' END)+@name+'\'+ @name + '_' + @fileDate + '.BAK'' WITH FILE = @backupSetId, NOUNLOAD, NOREWIND
58+
GO
59+
';
60+
61+
PRINT @BackupString;
62+
--PRINT @VerificationString;
63+
FETCH NEXT FROM db_cursor INTO @ID, @name;
64+
END
65+
66+
67+
CLOSE db_cursor
68+
DEALLOCATE db_cursor
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,44 @@
1+
/* Created By: AJAY DWIVEDI
2+
Created Date: NOV 23, 2014
3+
Purpose: Script out DB_OWNER
4+
Total Input: 1
5+
*/
6+
7+
DECLARE @db_name NVARCHAR(100)
8+
,@DB_Owner NVARCHAR(150)
9+
,@SQLString NVARCHAR(max)
10+
,@ID TINYINT
11+
,@TotalCount TINYINT;
12+
13+
--1) Specify your DB names for backup in case of data migration
14+
DECLARE database_cursor CURSOR FOR
15+
SELECT ROW_NUMBER()OVER(ORDER BY DB.name) AS ID, DB.name, SUSER_SNAME(DB.OWNER_SID) as DB_Owner
16+
FROM master.sys.databases AS DB
17+
--WHERE DB.name IN ('SomeDatabaseName1', 'manish', 'AdventureWorks'); --DB Migration
18+
WHERE DB.name NOT IN ('master','tempdb','model','msdb') --Instance Migration
19+
20+
OPEN database_cursor
21+
FETCH NEXT FROM database_cursor INTO @ID, @DB_Name, @DB_Owner;
22+
23+
WHILE @@FETCH_STATUS = 0
24+
BEGIN
25+
SET @SQLString = '
26+
--'+CAST(@ID AS VARCHAR(2))+')
27+
USE ['+@DB_Name+']
28+
GO
29+
IF (SELECT SUSER_SID('''+@DB_Owner+''') ) IS NOT NULL
30+
EXEC sp_changedbowner ['+@DB_Owner+']
31+
ELSE
32+
BEGIN
33+
PRINT ''DB_Owner ['+@DB_Owner+'] for ['+@DB_Name+'] database not found on Target Instance''
34+
EXEC sp_changedbowner [sa]
35+
END
36+
GO';
37+
38+
PRINT @SQLString;
39+
40+
FETCH NEXT FROM database_cursor INTO @ID, @DB_Name, @DB_Owner;
41+
END
42+
43+
CLOSE database_cursor
44+
DEALLOCATE database_cursor

0 commit comments

Comments
 (0)