-- =============================================
-- Author:
-- Blog:
-- Create date:
-- Description:
-- =============================================
DECLARE @DataBaseName SYSNAME--数据库名称
DECLARE @BackupPath SYSNAME--保存分区备份的路径
DECLARE @FilegroupName SYSNAME--分区文件组名称
DECLARE @sql NVARCHAR(MAX)--sql字符串
--设置下面变量
SET @DataBaseName = 'DataBaseName'
SET @BackupPath = 'D:\DBBackup\'
--1.设置完整模式
PRINT '--设置完整模式'
SET @sql = 'USE [master]
GO
ALTER DATABASE ['+@DataBaseName +'] SET RECOVERY FULL WITH NO_WAIT
GO'
PRINT @sql + CHAR(13)
--2.备份分区
DECLARE @itemCur CURSOR
SET @itemCur = CURSOR FOR
SELECT [name] FROM sys.filegroups ORDER BY is_default
OPEN @itemCur
FETCH NEXT FROM @itemCur INTO @FilegroupName
WHILE @@FETCH_STATUS=0
BEGIN
--逻辑处理
PRINT '--备份分区- ' + @FilegroupName
SET @sql = 'BACKUP DATABASE [' + @DataBaseName + ']
FILEGROUP = ''' + @FilegroupName + '''
TO DISK = ''' + @BackupPath+@FilegroupName + '.bak'' WITH FORMAT
GO'
PRINT @sql + CHAR(13)
FETCH NEXT FROM @itemCur INTO @FilegroupName
END
CLOSE @itemCur
DEALLOCATE @itemCur
--3.备份日志
PRINT '--备份日志'
SET @sql = 'BACKUP LOG [' + @DataBaseName + ']
TO DISK = ''' + @BackupPath+@DataBaseName + '_Log.bak'' WITH FORMAT
GO'
PRINT @sql + CHAR(13)
上面SQL脚本的逻辑是:
1. 首先设置数据库的恢复模式为完整恢复模式,这是为了后面对数据库的日志进行备份;
2. 通过当前数据库的系统表sys.filegroups拿到文件组的名称,这里把默认文件排在最后面,这是因为有可能会对配置表进行的操作,所以把这个文件组放到最后备份;
3. 使用游标的方式来循环文件组,生成文件组对应的备份SQL语句;
4. 最后备份数据库的日志,对文件组的还原是需要通过日志备份才能还原的;
在旧数据库执行上面的SQL脚本,将会产生生成下面的SQL(只保留了部分SQL):
--设置完整模式
USE [master]
GO
ALTER DATABASE [DataBaseName] SET RECOVERY FULL WITH NO_WAIT
GO
--备份分区- FG_Archive_Id_01
BACKUP DATABASE [DataBaseName]
FILEGROUP = 'FG_Archive_Id_01'
TO DISK = 'D:\DBBackup\FG_Archive_Id_01.bak' WITH FORMAT
GO
--备份分区- FG_Archive_Id_02
BACKUP DATABASE [DataBaseName]
FILEGROUP = 'FG_Archive_Id_02'
TO DISK = 'D:\DBBackup\FG_Archive_Id_02.bak' WITH FORMAT
GO
--备份分区- FG_Archive_Index
BACKUP DATABASE [DataBaseName]
FILEGROUP = 'FG_Archive_Index'
TO DISK = 'D:\DBBackup\FG_Archive_Index.bak' WITH FORMAT
GO
--备份分区- PRIMARY
BACKUP DATABASE [DataBaseName]
FILEGROUP = 'PRIMARY'
TO DISK = 'D:\DBBackup\PRIMARY.bak' WITH FORMAT
GO
--备份日志
BACKUP LOG [DataBaseName]
TO DISK = 'D:\DBBackup\Barefoot.Archives_Log.bak' WITH FORMAT
GO
执行完上面的脚本,会生成下图所示的备份文件:
(Figure4:备份文件列表)
-- =============================================
-- Author:
-- Blog:
-- Create date:
-- Description:
-- =============================================
DECLARE @DataBaseName SYSNAME--数据库名称
DECLARE @BackupPath SYSNAME--保存备份文件的路径
DECLARE @SavePath_Drive SYSNAME--保存数据库文件的盘符
DECLARE @SavePath_FolderName SYSNAME--保存数据库的文件夹
DECLARE @SavePath_SubFolderName SYSNAME--保存分区的文件夹
DECLARE @FilegroupName SYSNAME--分区文件组名称
DECLARE @FileName SYSNAME--分区文件名称
DECLARE @PhysicalName SYSNAME--物理路径
DECLARE @IsSamePath INT--是否跟远路径一样1,0
DECLARE @sql NVARCHAR(MAX)--sql字符串
--设置下面变量
SET @DataBaseName = 'DataBaseName'
SET @BackupPath = 'E:\DBBackup\'
SET @SavePath_Drive = 'F:\'
SET @SavePath_FolderName = 'DataBase\'
SET @SavePath_SubFolderName = 'FG_Archive\'
SET @IsSamePath = 1
--1.还原主分区
SELECT @FilegroupName = [name] FROM sys.filegroups WHERE is_default = 1
PRINT '--还原主分区'
SET @sql = 'RESTORE DATABASE [' + @DataBaseName + ']
FILEGROUP = ''' + @FilegroupName + '''
FROM DISK = ''' + @BackupPath + @FilegroupName + '.bak'' WITH FILE = 1,
MOVE N''' + @DataBaseName + ''' TO N''' + @SavePath_Drive + @SavePath_FolderName + @DataBaseName + '.mdf'',
MOVE N''' + @DataBaseName + '_log'' TO N''' + @SavePath_Drive + @SavePath_FolderName + @DataBaseName + '_log.ldf'',
NORECOVERY,REPLACE,STATS = 10
GO'
PRINT @sql + CHAR(13)
--2.还原分区
DECLARE @itemCur CURSOR
SET @itemCur = CURSOR FOR
SELECT df.[name] AS FileName, df.physical_name, fg.[name] AS FilegroupName
FROM sys.database_files df
JOIN sys.filegroups fg
ON df.data_space_id = fg.data_space_id
WHERE fg.is_default = 0
OPEN @itemCur
FETCH NEXT FROM @itemCur INTO @FileName,@PhysicalName,@FilegroupName
WHILE @@FETCH_STATUS=0
BEGIN
--逻辑处理
PRINT '--还原分区- ' + @FilegroupName
IF @IsSamePath = 0
SET @PhysicalName = @SavePath_Drive + @SavePath_FolderName + @SavePath_SubFolderName + '\' + @FileName + '.ndf'
ELSE
SET @PhysicalName = @SavePath_Drive + SUBSTRING(@PhysicalName,CHARINDEX('\',@PhysicalName)+1,LEN(@PhysicalName))
SET @sql = 'RESTORE DATABASE [' + @DataBaseName + ']
FILEGROUP = ''' + @FilegroupName + '''
FROM DISK = ''' + @BackupPath+@FilegroupName + '.bak'' WITH FILE = 1,
MOVE N''' + @FileName + '''
TO N''' + @PhysicalName + ''',
NORECOVERY
GO'
PRINT @sql + CHAR(13)
FETCH NEXT FROM @itemCur INTO @FileName,@PhysicalName,@FilegroupName
END
CLOSE @itemCur
DEALLOCATE @itemCur
--3.还原日志
PRINT '--还原日志'
SET @sql = 'RESTORE LOG [' + @DataBaseName + ']
FROM DISK = ''' + @BackupPath + @DataBaseName + '_Log.bak''
WITH NORECOVERY
GO'
PRINT @sql + CHAR(13)
--4.还原在线
PRINT '--还原在线'
SET @sql = 'RESTORE DATABASE [' + @DataBaseName + ']
WITH RECOVERY
GO'
PRINT @sql + CHAR(13)
上面SQL脚本的逻辑是:
1. 通过系统表sys.filegroups找到默认文件组,先还原这个主文件;
2. 使用游标的方式来循环系统表sys.filegroups,拿到文件组名称,生成文件组对应的还原SQL语句;
3. 接着还原数据库的日志;
4. 最后还原在线,让数据库在线;
执行上面的SQL脚本,将会产生生成下面的SQL(只保留了部分SQL):
--还原主分区
RESTORE DATABASE [DataBaseName]
FILEGROUP = 'PRIMARY'
FROM DISK = 'E:\DBBackup\PRIMARY.bak' WITH FILE = 1,
MOVE N'Barefoot.Archives' TO N'F:\DataBase\Barefoot.Archives.mdf',
MOVE N'Barefoot.Archives_log' TO N'F:\DataBase\Barefoot.Archives_log.ldf',
NORECOVERY,REPLACE,STATS = 10
GO
--还原分区- FG_Archive_Id_01
RESTORE DATABASE [DataBaseName]
FILEGROUP = 'FG_Archive_Id_01'
FROM DISK = 'E:\DBBackup\FG_Archive_Id_01.bak' WITH FILE = 1,
MOVE N'FG_Archive_Id_01_data'
TO N'F:\DataBase\FG_Archive\FG_Archive_Id_01_data.ndf',
NORECOVERY
GO
--还原分区- FG_Archive_Id_02
RESTORE DATABASE [DataBaseName]
FILEGROUP = 'FG_Archive_Id_02'
FROM DISK = 'E:\DBBackup\FG_Archive_Id_02.bak' WITH FILE = 1,
MOVE N'FG_Archive_Id_02_data'
TO N'F:\DataBase\FG_Archive\FG_Archive_Id_02_data.ndf',
NORECOVERY
GO
--还原分区- FG_Archive_Index
RESTORE DATABASE [DataBaseName]
FILEGROUP = 'FG_Archive_Index'
FROM DISK = 'E:\DBBackup\FG_Archive_Index.bak' WITH FILE = 1,
MOVE N'FG_Archive_Index_data'
TO N'F:\DataBase\Barefoot.Archives\FG_Archive_Index_data.ndf',
NORECOVERY
GO
--还原日志
RESTORE LOG [DataBaseName]
FROM DISK = 'E:\DBBackup\Barefoot.Archives_Log.bak'
WITH NORECOVERY
GO
--还原在线
RESTORE DATABASE [DataBaseName]
WITH RECOVERY
GO
在新服务器上执行上面的SQL脚本还原数据库,需要注意的是:在还原在线之前数据库都是一直处于:正在还原的状态的;
六.注意事项(Attention)
1. 在实际运用中,可以结合本文和SQL Server 数据库迁移偏方进行灵活结合运用,当通过本文件组备份后,旧库继续进数据,在花销时间最大的网络传输过程和还原过程继续对老库进数据,这样当还原好数据库之后使用SQL Server 数据库迁移偏方来转移最新的数据,这样宕机的时间会趋向于0;
2. 其实为了确保某些文件组不被修改,可以设置文件组的只读属性,这样可以确保只有某个文件组在进新数据,可惜的是设置了只读也无法拷贝这些文件组文件通过FTP传输,提示:操作无法完成,因为文件已在SQL Server(MSSQLSERVER)中打开。
3. 上面脚本的每个文件组中只包含了一个文件,如果一个文件组包含多个文件,那就需要修改下脚本了;
4. 高文佳曾经说过,可以先删除索引,再压缩备份,还原之后再创建索引,是的,这不防是一个好方法,不过需要考虑两点,一个是在还原之后创建索引的速度与时间,如果磁盘速度不算快,那你就要考虑删除索引是否适合了;另外一点是你的数据库是否能停机让你删除索引,这个跟具体的业务有关;
--备份分区
DECLARE @FileName VARCHAR(200)
SET @FileName = 'G:\DBBackup\FG_Archive_Id_05_null.bak'
BACKUP DATABASE [DataBaseName]
FILEGROUP='FG_Archive_Id_05' TO DISK=@FileName WITH FORMAT
GO
--还原分区
RESTORE DATABASE [DataBaseName]
FILEGROUP='FG_Archive_Id_05' FROM DISK='E:\DBBackup\FG_Archive_Id_05_null.bak' WITH FILE = 1,
MOVE N'FG_Archive_Id_05_data' TO N'E:\DataBase\FG_Archive\FG_Archive_Id_05_data.ndf',
NORECOVERY
GO
解答:从备份和还原的代码可以看出只是把FILEGROUP与bak对应,与ndf文件对应,所以是不需要理会这个文件组中包含了多少个逻辑分区;