- 工信部備案號 滇ICP備05000110號-1
- 滇公安備案 滇53010302000111
- 增值電信業務經營許可證 B1.B2-20181647、滇B1.B2-20190004
- 云南互聯網協會理事單位
- 安全聯盟認證網站身份V標記
- 域名注冊服務機構許可:滇D3-20230001
- 代理域名注冊服務機構:新網數碼
SQL Server 批量完?備份 實現方式三
使用存儲過程sp_MSforeachdb_Filter(以sp_MSforeachdb為基礎)
通過查看系統存儲過程sp_MSforeachdb的T-SQL源代碼可以發現是沒有提供@whereand參數可以過濾數據庫的,參考系統存儲過程sp_MSforeachtable后,在sp_MSforeachdb的基礎上創建帶@whereand參數的存儲過程sp_MSforeachdb_Filter,這樣你就可以讓SQL在指定的數據庫上執行;
-- ============================================= -- Create date: <2016.05.06> -- Description: <擴展sp_MSforeachdb,增加@whereand參數> -- ============================================= USE [master] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER OFF GO create proc [dbo].[sp_MSforeachdb_Filter] @command1 nvarchar(2000), @replacecharnchar(1) = N'?', @command2 nvarchar(2000) = null, @command3 nvarchar(2000) = null, @whereandnvarchar(2000) = null,@precommandnvarchar(2000) = null, @postcommandnvarchar(2000) = null as set deadlock_priority low /* This proc returns one or more rows for each accessible db, with each db defaulting to its own result set */ /* @precommand and @postcommand may be used to force a single result set via a temp table. */ /* Preprocessor won't replace within quotes so have to use str(). */ declare @inaccessible nvarchar(12), @invalidloginnvarchar(12), @dbinaccessiblenvarchar(12) select @inaccessible = ltrim(str(convert(int, 0x03e0), 11)) select @invalidlogin = ltrim(str(convert(int, 0x40000000), 11)) select @dbinaccessible = N'0x80000000' /* SQLDMODbUserProf_InaccessibleDb; the negative number doesn't work in convert() */ if (@precommand is not null) exec(@precommand) declare @origdbnvarchar(128) select @origdb = db_name() /* If it's a single user db and there's an entry for it in sysprocesses who isn't us, we can't use it. */ /* Create the select */ exec(N'declarehCForEachDatabase cursor global for select name from master.dbo.sysdatabases d ' + N' where (d.status& ' + @inaccessible + N' = 0)' + N' and (DATABASEPROPERTY(d.name, ''issingleuser'') = 0 and (has_dbaccess(d.name) = 1))' + @whereand) declare @retvalint select @retval = @@error if (@retval = 0) exec @retval = sys.sp_MSforeach_worker @command1, @replacechar, @command2, @command3, 1 if (@retval = 0 and @postcommand is not null) exec(@postcommand) declare @tempdbnvarchar(258) SELECT @tempdb = replace(@origdb, N']', N']]') exec (N'use ' + N'[' + @tempdb + N']') return @retval
上面的存儲過程sp_MSforeachdb_Filter與sp_MSforeachdb的區別有以下兩點:
(Figure1:添加內容1)
(Figure2:添加內容2)
而且需要注意在創建存儲過程的時候需要設置SET QUOTED_IDENTIFIER OFF,當 SET QUOTED_IDENTIFIER 為 ON 時,標識符可以由雙引號分隔,而文字必須由單引號分隔;當 SET QUOTED_IDENTIFIER 為 OFF 時,標識符不可加引號,且必須符合所有 Transact-SQL 標識符規則。具體可以參考:SET QUOTED_IDENTIFIER (Transact-SQL)
調用sp_MSforeachdb_Filter實現批量備份數據庫的T-SQL如下所示:
--使用更新的存儲過程sp_MSforeachdb_Filter(以sp_MSforeachdb為基礎) USE [master] GO DECLARE @SQL NVARchar(MAX) SELECT @SQL = COALESCE(@SQL,'') + ' BACKUP DATABASE [?] TO DISK = ''E:DBBackup?_' + CONVERT(char(8),GETDATE(),112) + CAST(DATEPART(hh, GETDATE()) AS VARCHAR) + CAST(DATEPART(mi, GETDATE()) AS VARCHAR) + '.bak'' WITH NOINIT, NOUNLOAD, NAME = N''?_backup'', NOSKIP, STATS = 10, NOFORMAT' PRINT @SQL --過濾數據庫 EXEC [sp_MSforeachdb_Filter] @command1=@SQL, @whereand=" and [name] not in('tempdb','master','model','msdb') "
執行上面的存儲過程就可以備份所有數據庫(系統數據庫除外,想要過濾數據庫可以填寫@whereand參數的條件),執行上面SQL的效果如下圖所示:
(Figure3:備份信息)
如果沒有設置SET QUOTED_IDENTIFIER 這個選項為 OFF ,那么在調用存儲過程sp_MSforeachdb_Filter的時候會出現下圖所示的錯誤信息:
(Figure4:錯誤信息)
如果想查看存儲過程sp_MSforeachdb的詳細代碼,可以在通過訪問路徑:數據庫-可編程性-存儲過程-系統存儲過程-sp_MSforeachdb找到,或者通過下面的腳本查看:
--顯示規則、默認值、未加密的存儲過程、用戶定義函數、觸發器或視圖的?本EXEC sp_helptext N'sp_MSforeachdb';
售前咨詢
售后咨詢
備案咨詢
二維碼
TOP