也是三部曲,首先是準備 PowerShell 的 restore script,接著是利用一個 batch file (.BAT) 啟動這個 script 檔案,最後就是在 Task Scheduler 創建一個 task 按時執行這個 batch file 就完成了。
PowerShell script file 稱為 SqlRestore.ps1,內容如下:
#============================================================ # Restore a Database using PowerShell and SQL Server SMO # Restore to the same database, overwrite existing db # Donabel Santos # 2010.10.16 paulus: modified #============================================================ #clear screen cls #load assemblies [System.Reflection.Assembly]::LoadWithPartialName("Microsoft.SqlServer.SMO") | Out-Null #Need SmoExtended for backup [System.Reflection.Assembly]::LoadWithPartialName("Microsoft.SqlServer.SmoExtended") | Out-Null [Reflection.Assembly]::LoadWithPartialName("Microsoft.SqlServer.ConnectionInfo") | Out-Null [Reflection.Assembly]::LoadWithPartialName("Microsoft.SqlServer.SmoEnum") | Out-Null #get backup file #you can also use PowerShell to query the last backup file based on the timestamp #I'll save that enhancement for later $backupFile = "C:MSSQLBackup" + $args[0] + ".bak" #we will query the db name from the backup file later $server = New-Object ("Microsoft.SqlServer.Management.Smo.Server") "(local)" $backupDevice = New-Object ("Microsoft.SqlServer.Management.Smo.BackupDeviceItem") ($backupFile, "File") $smoRestore = new-object("Microsoft.SqlServer.Management.Smo.Restore") #settings for restore $smoRestore.NoRecovery = $false; $smoRestore.Partial = $false $smoRestore.ReplaceDatabase = $true; $smoRestore.Action = "Database" #show every 10% progress $smoRestore.PercentCompleteNotification = 10; $smoRestore.Devices.Add($backupDevice) #read db name from the backup file's backup header $smoRestoreDetails = $smoRestore.ReadBackupHeader($server) #display database name "Database Name from Backup Header : " + $smoRestoreDetails.Rows[0]["DatabaseName"] $smoRestore.Database = $smoRestoreDetails.Rows[0]["DatabaseName"] #restore $smoRestore.SqlRestore($server) #2010.10.16 paulus: set owner to sa $db = New-Object Microsoft.SqlServer.Management.Smo.Database $db = $server.Databases.Item($smoRestoreDetails.Rows[0]["DatabaseName"]) $db.SetOwner("sa", $TRUE) "Done"
batch file 稱為 RestoreDb.bat,內容如下:
powershell -command "& {C:MSSQLSqlRestore.ps1 Club.Secretary}" powershell -command "& {C:MSSQLSqlRestore.ps1 Club.Secretary.RTIA}"
batch file 比較簡單,再來就是設立 Task Scheduler。如果 Task Scheduler 啟動的時間比 Backup 的時間早,就可以做成有兩天的備份了。
配合之前講的 Backup script 便建立了一個 SQL Server 的 mirrror server, 用作 disaster backup, 雖然不是 synchronized,難得是免費的,效果也算不壞吧?