1
+ /* --------------------------------------------------------------------------------------------------------------------------------+
2
+ | Purpose: Restore a backup of a database
3
+ | Example: EXEC admin.Restore_Primavera_Backup 'C:\Temp\PMDB1_20170519_073701_firstname.lastname.bak', 'PMDB1_TEST'
4
+ +--------------------------------------------------------------------------------------------------------------------------------*/
5
+
6
+ :setvar _server " Server1"
7
+ :setvar _user " ***username***"
8
+ :setvar _password " ***password***"
9
+ :setvar _database " master"
10
+ :connect $(_server) - U $(_user) - P $(_password)
11
+
12
+ USE [$(_database)];
13
+ GO
14
+
15
+
16
+ CREATE PROCEDURE [admin].[Restore_Primavera_Backup]
17
+ (
18
+ @FileName VARCHAR (255 )
19
+ , @DatabaseName VARCHAR (50 )
20
+ )
21
+ AS
22
+ BEGIN
23
+
24
+ PRINT ' ====================================================================='
25
+ PRINT ' check if the database exists first...'
26
+ PRINT ' ====================================================================='
27
+
28
+ IF (NOT EXISTS (SELECT name FROM master .dbo .sysdatabases WHERE name = @DatabaseName))
29
+ BEGIN
30
+
31
+ PRINT ' ====================================================================='
32
+ PRINT ' set the name and path for the restore...'
33
+ PRINT ' ====================================================================='
34
+ DECLARE @DataFile VARCHAR (200 )
35
+
36
+ PRINT ' ====================================================================='
37
+ PRINT ' set the data path for sql server...'
38
+ PRINT ' ====================================================================='
39
+
40
+ SELECT @DataFile = SUBSTRING (physical_name, 1 , CHARINDEX (N ' master.mdf' , LOWER (physical_name)) - 1 )
41
+ FROM master .sys .master_files
42
+ WHERE database_id = 1 AND file_id = 1
43
+
44
+ PRINT ' ====================================================================='
45
+ PRINT ' get the logical names from the backup file...'
46
+ PRINT ' ====================================================================='
47
+ DECLARE @Table TABLE (
48
+ [LogicalName] varchar (128 )
49
+ , [PhysicalName] varchar (128 )
50
+ , [Type] varchar
51
+ , [FileGroupName] varchar (128 )
52
+ , [Size] varchar (128 )
53
+ , [MaxSize] varchar (128 )
54
+ , [FileId]varchar (128 )
55
+ , [CreateLSN]varchar (128 )
56
+ , [DropLSN]varchar (128 )
57
+ , [UniqueId]varchar (128 )
58
+ , [ReadOnlyLSN]varchar (128 )
59
+ , [ReadWriteLSN]varchar (128 )
60
+ , [BackupSizeInBytes]varchar (128 )
61
+ , [SourceBlockSize]varchar (128 )
62
+ , [FileGroupId]varchar (128 )
63
+ , [LogGroupGUID]varchar (128 )
64
+ , [DifferentialBaseLSN]varchar (128 )
65
+ , [DifferentialBaseGUID]varchar (128 )
66
+ , [IsReadOnly]varchar (128 )
67
+ , [IsPresent]varchar (128 )
68
+ , [TDEThumbprint]varchar (128 )
69
+ )
70
+
71
+ DECLARE @LogicalNameData varchar (128 )
72
+ DECLARE @LogicalNameLog varchar (128 )
73
+ INSERT INTO @table EXEC (' RESTORE FILELISTONLY FROM DISK='' ' + @FileName + ' '' ' )
74
+
75
+ SET @LogicalNameData= (SELECT LogicalName FROM @Table WHERE Type = ' D' )
76
+ SET @LogicalNameLog= (SELECT LogicalName FROM @Table WHERE Type = ' L' )
77
+
78
+ PRINT ' ====================================================================='
79
+ PRINT ' Restore the Database starting with a file from a Full Backup...'
80
+ PRINT ' ====================================================================='
81
+ BEGIN
82
+ DECLARE @RESTORE_SQL VARCHAR (MAX )
83
+ SET @RESTORE_SQL =
84
+ ' RESTORE DATABASE ' + @DatabaseName + '
85
+ FROM DISK = '' ' + @FileName + ' ''
86
+ WITH
87
+ RECOVERY
88
+ , STATS = 10
89
+ , MOVE '' ' + @LogicalNameData + ' '' TO '' ' + @DataFile + @DatabaseName + ' .mdf''
90
+ , MOVE '' ' + @LogicalNameLog + ' '' TO '' ' + @DataFile + @DatabaseName + ' .ldf'' '
91
+ PRINT @RESTORE_SQL
92
+ EXEC (@RESTORE_SQL)
93
+ END
94
+
95
+ PRINT ' ====================================================================='
96
+ PRINT ' Update owner of the database to standard...'
97
+ PRINT ' ====================================================================='
98
+ BEGIN
99
+ DECLARE @OWNER_SQL VARCHAR (MAX )
100
+ SET @OWNER_SQL = ' ALTER AUTHORIZATION ON DATABASE::' + @DatabaseName + ' TO sa;'
101
+ PRINT @OWNER_SQL
102
+ EXEC (@OWNER_SQL)
103
+ END
104
+
105
+ PRINT ' ====================================================================='
106
+ PRINT ' Restore system user logins...'
107
+ PRINT ' ====================================================================='
108
+
109
+ DECLARE @sql NVARCHAR (255 );
110
+ SET @sql = ' USE ' + @DatabaseName + ' ; EXEC dbo.sp_change_users_login '' Update_One'' , '' privuser'' , '' privuser'' ; ' ;
111
+
112
+ PRINT @sql
113
+ EXEC (@sql)
114
+
115
+ SET @sql = ' USE ' + @DatabaseName + ' ; EXEC dbo.sp_change_users_login '' Update_One'' , '' pubuser'' , '' pubuser'' ; ' ;
116
+
117
+ PRINT @sql
118
+ EXEC (@sql)
119
+
120
+ PRINT ' ====================================================================='
121
+ PRINT ' Restore system jobs if they havent already been setup...'
122
+ PRINT ' ====================================================================='
123
+
124
+ SET @sql = ' USE ' + @DatabaseName + ' ; EXEC initialize_background_procs; ' ;
125
+
126
+ PRINT @sql
127
+ EXEC (@sql)
128
+
129
+ SET @sql = ' USE ' + @DatabaseName + ' ; EXEC system_monitor; ' ;
130
+
131
+ PRINT @sql
132
+ EXEC (@sql)
133
+
134
+ SET @sql = ' USE ' + @DatabaseName + ' ; EXEC data_monitor; ' ;
135
+
136
+ PRINT @sql
137
+ EXEC (@sql)
138
+
139
+ PRINT ' ====================================================================='
140
+ PRINT ' Finished!'
141
+ PRINT ' ====================================================================='
142
+
143
+ END
144
+
145
+ END ;
146
+
147
+ GO
0 commit comments