备份和还原数据库和事务日志

在 SMO 中,Backup 类和 Restore 类是为实现特定备份和还原任务提供工具的实用工具类。Backup 对象(而不是服务器实例中的 Microsoft SQL Server 对象)表示所需的特定备份任务。

如果发生数据丢失或损坏,则必须完全或部分还原备份。部分还原使用 FileGroupCollection 集合将要进行还原的数据分成段。如果要对事务日志进行备份,则可以使用 Restore 对象的 ToPointInTime 属性将数据还原到特定时间点。还可以采用 SqlVerify 方法来验证数据。建议采用的备份过程是,通过定期进行还原操作并检查数据库中的数据来检查备份的完整性。

Backup 对象相同,无需采用 Create 方法创建 Restore 对象,因为该对象并不表示 SQL Server 实例中的任何对象。Restore 对象具有还原数据库所需的一组属性和方法。

示例

若要使用所提供的任何代码示例,您必须选择创建应用程序所需的编程环境、编程模板和编程语言。有关详细信息,请参阅如何在 Visual Studio .NET 中创建 Visual Basic SMO 项目如何在 Visual Studio .NET 中创建 Visual C# SMO 项目

在 Visual Basic 中备份数据库和事务日志

此代码示例说明如何将现有数据库备份到某个文件,以及如何还原该数据库。

'Connect to the local, default instance of SQL Server.
Dim srv As Server
srv = New Server
'Reference the AdventureWorks2008R2 database.
Dim db As Database
db = srv.Databases("AdventureWorks2008R2")
'Store the current recovery model in a variable.
Dim recoverymod As Integer
recoverymod = db.DatabaseOptions.RecoveryModel
'Define a Backup object variable. 
Dim bk As New Backup
'Specify the type of backup, the description, the name, and the database to be backed up.
bk.Action = BackupActionType.Database
bk.BackupSetDescription = "Full backup of AdventureWorks2008R2"
bk.BackupSetName = "AdventureWorks 2008R2 Backup"
bk.Database = "AdventureWorks2008R2"
'Declare a BackupDeviceItem by supplying the backup device file name in the constructor, and the type of device is a file.
Dim bdi As BackupDeviceItem
bdi = New BackupDeviceItem("Test_Full_Backup1", DeviceType.File)
'Add the device to the Backup object.
bk.Devices.Add(bdi)
'Set the Incremental property to False to specify that this is a full database backup.
bk.Incremental = False
'Set the expiration date.
Dim backupdate As New Date
backupdate = New Date(2006, 10, 5)
bk.ExpirationDate = backupdate
'Specify that the log must be truncated after the backup is complete.
bk.LogTruncation = BackupTruncateLogType.Truncate
'Run SqlBackup to perform the full database backup on the instance of SQL Server.
bk.SqlBackup(srv)
'Inform the user that the backup has been completed.
Console.WriteLine("Full Backup complete.")
'Remove the backup device from the Backup object.
bk.Devices.Remove(bdi)
'Make a change to the database, in this case, add a table called test_table.
Dim t As Table
t = New Table(db, "test_table")
Dim c As Column
c = New Column(t, "col", DataType.Int)
t.Columns.Add(c)
t.Create()
'Create another file device for the differential backup and add the Backup object.
Dim bdid As BackupDeviceItem
bdid = New BackupDeviceItem("Test_Differential_Backup1", DeviceType.File)
'Add the device to the Backup object.
bk.Devices.Add(bdid)
'Set the Incremental property to True for a differential backup.
bk.Incremental = True
'Run SqlBackup to perform the incremental database backup on the instance of SQL Server.
bk.SqlBackup(srv)
'Inform the user that the differential backup is complete.
Console.WriteLine("Differential Backup complete.")
'Remove the device from the Backup object.
bk.Devices.Remove(bdid)
'Delete the AdventureWorks2008R2 database before restoring it.
srv.Databases("AdventureWorks2008R2").Drop()
'Define a Restore object variable.
Dim rs As Restore
rs = New Restore
'Set the NoRecovery property to true, so the transactions are not recovered.
rs.NoRecovery = True
'Add the device that contains the full database backup to the Restore object.
rs.Devices.Add(bdi)
'Specify the database name.
rs.Database = "AdventureWorks2008R2"
'Restore the full database backup with no recovery.
rs.SqlRestore(srv)
'Inform the user that the Full Database Restore is complete.
Console.WriteLine("Full Database Restore complete.")
'Remove the device from the Restore object.
rs.Devices.Remove(bdi)
'Set te NoRecovery property to False.
rs.NoRecovery = False
'Add the device that contains the differential backup to the Restore object.
rs.Devices.Add(bdid)
'Restore the differential database backup with recovery.
rs.SqlRestore(srv)
'Inform the user that the differential database restore is complete.
Console.WriteLine("Differential Database Restore complete.")
'Remove the device.
rs.Devices.Remove(bdid)
'Set the database recovery mode back to its original value.
srv.Databases("AdventureWorks2008R2").DatabaseOptions.RecoveryModel = recoverymod
'Drop the table that was added.
srv.Databases("AdventureWorks2008R2").Tables("test_table").Drop()
srv.Databases("AdventureWorks2008R2").Alter()
'Remove the backup files from the hard disk.
My.Computer.FileSystem.DeleteFile("C:\Program Files\Microsoft SQL Server\MSSQL.1\MSSQL\Backup\Test_Full_Backup1")
My.Computer.FileSystem.DeleteFile("C:\Program Files\Microsoft SQL Server\MSSQL.1\MSSQL\Backup\Test_Differential_Backup1")

在 Visual C# 中备份数据库和事务日志

此代码示例说明如何将现有数据库备份到某个文件,以及如何还原该数据库。

{
            //Connect to the local, default instance of SQL Server. 
            Server srv = new Server();
            //Reference the AdventureWorks2008R2 database. 
            Database db = default(Database);
            db = srv.Databases["AdventureWorks2008R2"];
          
            //Store the current recovery model in a variable. 
            int recoverymod;
            recoverymod = (int)db.DatabaseOptions.RecoveryModel;

            //Define a Backup object variable. 
            Backup bk = new Backup();

            //Specify the type of backup, the description, the name, and the database to be backed up. 
            bk.Action = BackupActionType.Database;
            bk.BackupSetDescription = "Full backup of Adventureworks2008R2";
            bk.BackupSetName = "AdventureWorks2008R2 Backup";
            bk.Database = "AdventureWorks2008R2";
      
            //Declare a BackupDeviceItem by supplying the backup device file name in the constructor, and the type of device is a file. 
            BackupDeviceItem bdi = default(BackupDeviceItem);
            bdi = new BackupDeviceItem("Test_Full_Backup1", DeviceType.File);

            //Add the device to the Backup object. 
            bk.Devices.Add(bdi);
            //Set the Incremental property to False to specify that this is a full database backup. 
            bk.Incremental = false;

            //Set the expiration date. 
            System.DateTime backupdate = new System.DateTime();
            backupdate = new System.DateTime(2006, 10, 5);
            bk.ExpirationDate = backupdate;

            //Specify that the log must be truncated after the backup is complete. 
            bk.LogTruncation = BackupTruncateLogType.Truncate;

            //Run SqlBackup to perform the full database backup on the instance of SQL Server. 
            bk.SqlBackup(srv);

            //Inform the user that the backup has been completed. 
            Console.WriteLine("Full Backup complete.");

            //Remove the backup device from the Backup object. 
            bk.Devices.Remove(bdi);

            //Make a change to the database, in this case, add a table called test_table. 
            Table t = default(Table);
            t = new Table(db, "test_table");
            Column c = default(Column);
            c = new Column(t, "col", DataType.Int);
            t.Columns.Add(c);
            t.Create();

            //Create another file device for the differential backup and add the Backup object. 
            BackupDeviceItem bdid = default(BackupDeviceItem);
            bdid = new BackupDeviceItem("Test_Differential_Backup1", DeviceType.File);

            //Add the device to the Backup object. 
            bk.Devices.Add(bdid);

            //Set the Incremental property to True for a differential backup. 
            bk.Incremental = true;

            //Run SqlBackup to perform the incremental database backup on the instance of SQL Server. 
            bk.SqlBackup(srv);

            //Inform the user that the differential backup is complete. 
            Console.WriteLine("Differential Backup complete.");

            //Remove the device from the Backup object. 
            bk.Devices.Remove(bdid);

            //Delete the AdventureWorks2008R2 database before restoring it
           // db.Drop();

            //Define a Restore object variable.
            Restore rs = new Restore();

            //Set the NoRecovery property to true, so the transactions are not recovered. 
            rs.NoRecovery = true;

            //Add the device that contains the full database backup to the Restore object. 
            rs.Devices.Add(bdi);

            //Specify the database name. 
            rs.Database = "AdventureWorks2008R2";

            //Restore the full database backup with no recovery. 
            rs.SqlRestore(srv);

            //Inform the user that the Full Database Restore is complete. 
            Console.WriteLine("Full Database Restore complete.");

            //reacquire a reference to the database
            db = srv.Databases["AdventureWorks2008R2"];

            //Remove the device from the Restore object.
            rs.Devices.Remove(bdi);

            //Set the NoRecovery property to False. 
            rs.NoRecovery = false;

            //Add the device that contains the differential backup to the Restore object. 
            rs.Devices.Add(bdid);

            //Restore the differential database backup with recovery. 
            rs.SqlRestore(srv);

            //Inform the user that the differential database restore is complete. 
            Console.WriteLine("Differential Database Restore complete.");

            //Remove the device. 
            rs.Devices.Remove(bdid);

            //Set the database recovery mode back to its original value.
            db.RecoveryModel = (RecoveryModel)recoverymod;
          
            //Drop the table that was added. 
            db.Tables["test_table"].Drop();
            db.Alter();

            //Remove the backup files from the hard disk.
            //This location is dependent on the installation of SQL Server
            File.Delete("C:\\Program Files\\Microsoft SQL Server\\MSSQL10.MSSQLSERVER\\MSSQL\\Backup\\Test_Full_Backup1");
        File.Delete("C:\\Program Files\\Microsoft SQL Server\\MSSQL10.MSSQLSERVER\\MSSQL\\Backup\\Test_Differential_Backup1");
        
        } 

在 PowerShell 中备份数据库和事务日志

此代码示例说明如何将现有数据库备份到某个文件,以及如何还原该数据库。

#Backing up and restoring a Database from PowerShell

#Connect to the local, default instance of SQL Server.

#Get a server object which corresponds to the default instance
$srv = New-Object -TypeName Microsoft.SqlServer.Management.SMO.Server

#Reference the AdventureWorks database.
$db = $srv.Databases["AdventureWorks"]

#Store the current recovery model in a variable.
$recoverymod = $db.DatabaseOptions.RecoveryModel

#Create a Backup object
$bk = New-Object -TypeName Microsoft.SqlServer.Management.SMO.Backup

#set to backup the database
$bk.Action = [Microsoft.SqlServer.Management.SMO.BackupActionType]::Database

#Set back up properties
$bk.BackupSetDescription = "Full backup of AdventureWorks"
$bk.BackupSetName = "AdventureWorks Backup"
$bk.Database = "AdventureWorks"

#Declare a BackupDeviceItem by supplying the backup device file name in the constructor, 
#and the type of device is a file.
$dt = [Microsoft.SqlServer.Management.SMO.DeviceType]::File
$bdi = New-Object -TypeName Microsoft.SqlServer.Management.SMO.BackupDeviceItem `
-argumentlist "Test_FullBackup1", $dt

#Add the device to the Backup object.
$bk.Devices.Add($bdi)

#Set the Incremental property to False to specify that this is a full database backup.
$bk.Incremental = $false

#Set the expiration date.
$bk.ExpirationDate = get-date "10/05/2006"

#Specify that the log must be truncated after the backup is complete.
$bk.LogTruncation = [Microsoft.SqlServer.Management.SMO.BackupTruncateLogType]::Truncate

#Run SqlBackup to perform the full database backup on the instance of SQL Server.
$bk.SqlBackup($srv)

#Inform the user that the backup has been completed.
"Full Backup complete."

#Remove the backup device from the Backup object.
$bk.Devices.Remove($bdi)

#Make a change to the database, in this case, add a table called test_table.
$t = New-Object -TypeName Microsoft.SqlServer.Management.SMO.Table -argumentlist $db, "test_table"
$type = [Microsoft.SqlServer.Management.SMO.DataType]::int
$c = New-Object -TypeName Microsoft.SqlServer.Management.SMO.Column -argumentlist $t, "col", $type     
$t.Columns.Add($c)
$t.Create()

#Create another file device for the differential backup and add the Backup object.
# $dt is file backup device
$bdid = New-Object -TypeName Microsoft.SqlServer.Management.SMO.BackupDeviceItem `
-argumentlist "Test_DifferentialBackup1", $dt
#Add this device to the backup set
$bk.Devices.Add($bdid)

#Set the Incremental property to True for a differential backup.
$bk.Incremental = $true

#Run SqlBackup to perform the incremental database backup on the instance of SQL Server.
$bk.SqlBackup($srv)

#Inform the user that the differential backup is complete.
"Differential Backup complete."

#Remove the device from the Backup object.
$bk.Devices.Remove($bdid)

#Delete the AdventureWorks database before restoring it.
$db.Drop()

#Define a Restore object variable.
$rs = New-Object -TypeName Microsoft.SqlServer.Management.SMO.Restore

#Set the NoRecovery property to true, so the transactions are not recovered.
$rs.NoRecovery = $true

#Add the device that contains the full database backup to the Restore object.
$rs.Devices.Add($bdi)

#Specify the database name.
$rs.Database = "AdventureWorks"
#Restore the full database backup with no recovery.
$rs.SqlRestore($srv)

#Inform the user that the Full Database Restore is complete.
"Full Database Restore complete."

#Remove the device from the Restore object.
$rs.Devices.Remove($bdi)

#Set the NoRecovery property to False.
$rs.NoRecovery = $false

#Add the device that contains the differential backup to the Restore object.
$rs.Devices.Add($bdid)

#Restore the differential database backup with recovery.
$rs.SqlRestore($srv)

#Inform the user that the differential database restore is complete.
"Differential Database Restore complete."
       
#Remove the device.
$rs.Devices.Remove($bdid)

#Set the database recovery mode back to its original value.
$db = $srv.Databases["AdventureWorks"]
$db.DatabaseOptions.RecoveryModel = $recoverymod

#Drop the table that was added.
$db.Tables["test_table"].Drop()
$db.Alter()

#Delete the backup files - the exact location depends on your installation
del "C:\Program Files\Microsoft SQL Server\MSSQL10.MSSQLSERVER\MSSQL\Backup\Test_FullBackup1"
del "C:\Program Files\Microsoft SQL Server\MSSQL10.MSSQLSERVER\MSSQL\Backup\Test_DifferentialBackup1"

在 Visual Basic 中运行数据库完整性检查

SQL Server 提供数据完整性检查。此代码示例对指定的数据库运行数据库一致性类型检查。在此示例中,使用了 CheckTables,但也可以相似的方式使用 CheckAllocationsCheckCatalogCheckIdentityValues

注意注意

StringCollection 对象需要使用 imports System.Collections.Specialized 语句引用命名空间。

'Connect to the local, default instance of SQL Server.
Dim srv As Server
srv = New Server
'Reference the AdventureWorks2008R2 database.
Dim db As Database
db = srv.Databases("AdventureWorks2008R2")
'Note, to use the StringCollection type the System.Collections.Specialized system namespace must be included in the imports statements.
Dim sc As StringCollection
'Run the CheckTables method and display the results from the returned StringCollection variable.
sc = db.CheckTables(RepairType.None)
Dim c As Integer
For c = 0 To sc.Count - 1
    Console.WriteLine(sc.Item(c))
Next

在 Visual C# 中运行数据库完整性检查

SQL Server 提供数据完整性检查。此代码示例对指定的数据库运行数据库一致性类型检查。在此示例中,使用了 CheckTables,但也可以相似的方式使用 CheckAllocationsCheckCatalogCheckIdentityValues

注意注意

StringCollection 对象需要使用 imports System.Collections.Specialized 语句引用命名空间。

{
            //Connect to the local, default instance of SQL Server. 
            Server srv = new Server();

            //Reference the AdventureWorks2008R2 database.           
            Database db = srv.Databases["AdventureWorks2008R2"];

            //Note, to use the StringCollection type the System.Collections.Specialized system namespace must be included in the imports statements. 
            System.Collections.Specialized.StringCollection sc;

            //Run the CheckTables method and display the results from the returned StringCollection variable. 
            sc = db.CheckTables(RepairType.None);
           
            foreach (string c in sc)
            {
                Console.WriteLine(c);
            }
        }

在 PowerShell 中运行数据库完整性检查

SQL Server 提供数据完整性检查。此代码示例对指定的数据库运行数据库一致性类型检查。在此示例中,使用了 CheckTables,但也可以相似的方式使用 CheckAllocationsCheckCatalogCheckIdentityValues

注意注意

StringCollection 对象需要使用 imports System.Collections.Specialized 语句引用命名空间。

# Set the path context to the local, default instance of SQL Server and get a reference to AdventureWorks2008R2
CD \sql\localhost\default\databases
$db = get-item Adventureworks2008R2

$sc = $db.CheckTables([Microsoft.SqlServer.Management.SMO.RepairType]::None)
foreach ($c in $sc)
{
    $c
 }