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
|
-----------------------------------------------------------------------------
--- Generate DB restore script using SQL Backup
--- Author : Jerome Duquène
--- Last review : 2008/04/09
---
--- Description :
--- As first step, this script will create the procedure SYS_getDatabaseFileNames.
--- Then based on the configured value for the target server and the list of DB to restore
--- it will generate the restore script.
--- Finally it will remove the stored procedure.
--- This script works if the server name is 14 char long and if it exists a share called like 'Backups_XXXXX'
--- where XXXXX is last 5 characters of the servername
---
--- Usage :
--- Configure the data, log and index paths
--- Configure the list of DB to restore
--- Configure the backup date
--- Configure the backup instance name
--- Run this script on the source server
--- Run the output script on the target server
----------------------------------------------------
SET nocount on
if exists(select * from sysobjects where name = 'SYS_getDatabaseFilenames' and xtype = 'p')
begin
drop procedure SYS_getDatabaseFilenames
end
GO
Create procedure SYS_getDatabaseFilenames
@db varchar(255) = null --dbname
as
declare @i int --Counter
declare @insertStatement varchar (700) --build dynamicaly
if exists(select * from sysobjects where name = 'SYS_DatabasesFiles' and xtype = 'U')
BEGIN
drop table SYS_DatabasesFiles
END
create table SYS_DatabasesFiles
(
id int identity(1,1)
,DBName varchar(255)
,Logical_FileName varchar(255)
,Physical_FileName varchar(1000)
)
if @db is null
begin
select dbid, name
into #DBNames
from master.dbo.sysdatabases
order by dbid
set @i = 1
while @i <= (select max(dbid) from #DBNames)
BEGIN
select @db = name from #DBNames where dbid = @i
set @insertStatement = 'insert into SYS_DatabasesFiles(DBName, Logical_FileName, Physical_FileName) select distinct ''' + @db + ''', name, fileName from ' + @db + '.dbo.sysfiles'
exec (@insertStatement)
set @i = @i + 1
END
end
else
begin
set @insertStatement = 'insert into SYS_DatabasesFiles(DBName, Logical_FileName, Physical_FileName) select distinct ''' + @db + ''', name, fileName from ' + @db + '.dbo.sysfiles'
exec (@insertStatement)
end
-- set @i = 1
--
-- while @i <= (select max(dbid) from #DBNames)
-- BEGIN
-- select @db = name from #DBNames where dbid = @i
--
-- set @insertStatement = 'insert into SYS_DatabasesFiles(DBName, Logical_FileName, Physical_FileName) select distinct ''' + @db + ''', name, fileName from ' + @db + '.dbo.sysfiles'
--
-- exec (@insertStatement)
--
-- set @i = @i + 1
-- END
select distinct DBName, Logical_filename, physical_filename from SYS_DatabasesFiles
if exists(select * from tempdb.dbo.sysobjects where name = '#DBNames' and xtype = 'U')
begin
drop table #DBNames
end
drop table SYS_DatabasesFiles
GO
----------------------------------------------------
---
--- Please configure where to restore DB files here
---
----------------------------------------------------
set nocount on
declare @db varchar(255)
declare @backupDate varchar(8)
declare @sourceServer varchar(100)
declare @destinationDataPath varchar(500)
declare @destinationLogPath varchar(500)
declare @destinationIndexPath varchar(500)
declare @bckInstance varchar(20)
declare @filename varchar(70)
declare @i int
declare @fc int -- file counter
declare @lfn varchar(100) -- logical file name
declare @pfn varchar(100) -- physical file name
declare @lastChar int
declare @pos int
declare @files varchar(1000)
--------------------------------------------------------------
-- Define the backup date here --
-- /!\ if there are 2 different backups from the same date, --
-- /!\ for the same DB, this script will fail --
--------------------------------------------------------------
--------------------------
--
-- Configuration section
--
--------------------------
set @backupDate = '20080311'
set @bckInstance = '(local)' -- default = (local)
--set @sourceServer = 'serveurName'
set @destinationDataPath = 'c:\test\data'
set @destinationLogPath = 'c:\test\log'
set @destinationIndexPath = 'c:\test\index'
create table #dbName
(
id int identity(1,1),
dbName varchar(255)
)
insert into #dbName
select name from master.dbo.sysdatabases
where name in ('msdb','model','master', 'Djetmp2' ,'SNPTemp') -- name of the DB you want to restore
-----------------------------
--
-- End Configuration section
--
-----------------------------
set @i = 1
while @i <= (select max(id) from #dbName)
BEGIN
set @files = ''
select @db = dbName from #dbName where id = @i
create table #dbFiles
(
id int identity(1,1),
dbname varchar(100),
logical_filename varchar(500),
physical_filename varchar(500)
)
-- print 'print ''Restoring ' + @db + ''''
-- print 'exec sp_shutdowndbusers ''' + @db + ''''
-- print 'exec master..sqlbackup N''-SQL "RESTORE DATABASE [' + @db + '] FROM DISK = ''''\\' + left(@@servername,14) + '\Backups_' + right(@@servername,5) + '\' + @db + '\FULL_(local)_' + @db + '_' + @backupDate + '*.sqb'''' WITH RECOVERY, MOVE ''''' + @db + '_Data'''' TO ''''' + @destinationDataPath + '\' + @db + '_data.mdf'''', MOVE ''''' + @db + '_Log'''' TO ''''' + @destinationLogPath + '\' + @db + '_log.ldf''''"'''
-- print 'GO'
insert into #dbFiles
exec SYS_getDatabaseFilenames @db
set @fc = 1
while @fc <= (select max(id) from #dbFiles)
begin
select @lfn = rtrim(ltrim(logical_filename)), @pfn = physical_filename from #dbFiles where id = @fc
set @pos = 1
-- get last '\' in the physical file name
while (@pos <> 0)
begin
set @lastChar = @pos
set @pos = charindex('\',@pfn, @lastChar + 1)
end
set @pfn = substring(@pfn,@lastChar + 1, len(@pfn) - @lastchar) -- At this step, @pfn contain the real filename
select @files = case (upper(right(@pfn,3)))
when 'LDF' then @files + ', MOVE ''''' + @lfn + ''''' TO ''''' + @destinationLogPath + '\' + @pfn + ''''''
when 'MDF' then @files + ', MOVE ''''' + @lfn + ''''' TO ''''' + @destinationDataPath + '\' + @pfn + ''''''
else @files + ', MOVE ''''' + @lfn + ''''' TO ''''' + @destinationIndexPath + '\' + @pfn + ''''''
end
set @fc = @fc + 1
end
print 'print ''Restoring ' + @db + ''''
print 'exec sp_shutdowndbusers ''' + @db + ''''
print 'exec master..sqlbackup N''-SQL "RESTORE DATABASE [' + @db + '] FROM DISK = ''''\\' + left(@@servername,14) + '\Backups_' + right(left(@@servername,14),5) + '\' + @db + '\FULL_' + @bckInstance + '_' + @db + '_' + @backupDate + '*.sqb'''' WITH RECOVERY, REPLACE' + @files + '"'''
print 'GO'
drop table #dbFiles
set @i = @i + 1
END
drop table #dbName
GO
SET nocount on
if exists(select * from sysobjects where name = 'SYS_getDatabaseFilenames' and xtype = 'p')
begin
drop procedure SYS_getDatabaseFilenames
end
GO |
Partager