1.簡(jiǎn)介:
作為DBA會(huì)經(jīng)常需要檢查所有的數(shù)據(jù)庫(kù)或用戶表,比如:檢查所有數(shù)據(jù)庫(kù)的容量;看看指定數(shù)據(jù)庫(kù)所有用戶表的容量,所有表的記錄數(shù)...,我們一般處理這樣的問題都是用游標(biāo)分別處理處理,比如:在數(shù)據(jù)庫(kù)檢索效率非常慢時(shí),我們想檢查數(shù)據(jù)庫(kù)所有的用戶表,我們就必須通過寫游標(biāo)來達(dá)到要求;如果我們用sp_MSforeachtable就可以非常方便的達(dá)到相同的目的:EXEC sp_MSforeachtable @command1="print '?' DBCC CHECKTABLE ('?')"
系統(tǒng)存儲(chǔ)過程sp_MSforeachtable和sp_MSforeachdb,是微軟提供的兩個(gè)不公開的存儲(chǔ)過程,從mssql6.5開始蒿柳。存放在SQL Server的MASTER數(shù)據(jù)庫(kù)中′鲶。可以用來對(duì)某個(gè)數(shù)據(jù)庫(kù)的所有表或某個(gè)SQL服務(wù)器上的所有數(shù)據(jù)庫(kù)進(jìn)行管理垒探,后面將對(duì)此進(jìn)行詳細(xì)介紹。
2.參數(shù)說明:
@command1 nvarchar(2000), --第一條運(yùn)行的SQL指令
@replacechar nchar(1) = N'?', --指定的占位符號(hào)
@command2 nvarchar(2000)= null, --第二條運(yùn)行的SQL指令
@command3 nvarchar(2000)= null, --第三條運(yùn)行的SQL指令
@whereand nvarchar(2000)= null, --可選條件來選擇表
@precommand nvarchar(2000)= null, --執(zhí)行指令前的操作(類似控件的觸發(fā)前的操作)
@postcommand nvarchar(2000)= null --執(zhí)行指令后的操作(類似控件的觸發(fā)后的操作)
以后為sp_MSforeachtable的參數(shù)怠李,sp_MSforeachdb不包括參數(shù)@whereand
3.使用舉例:
--統(tǒng)計(jì)數(shù)據(jù)庫(kù)里每個(gè)表的詳細(xì)情況:
exec sp_MSforeachtable @command1="sp_spaceused '?'"
--獲得每個(gè)表的記錄數(shù)和容量:
EXEC sp_MSforeachtable @command1="print '?'",
@command2="sp_spaceused '?'",
@command3= "SELECT count(*) FROM ? "
--獲得所有的數(shù)據(jù)庫(kù)的存儲(chǔ)空間:
EXEC sp_MSforeachdb @command1="print '?'",
@command2="sp_spaceused "
--檢查所有的數(shù)據(jù)庫(kù)
EXEC sp_MSforeachdb @command1="print '?'",
@command2="DBCC CHECKDB (?) "
--更新PUBS數(shù)據(jù)庫(kù)中已t開頭的所有表的統(tǒng)計(jì):
EXEC sp_MSforeachtable @whereand="and name like 't%'",
@replacechar='*',
@precommand="print 'Updating Statistics.....' print ''",
@command1="print '*' update statistics * ",
@postcommand= "print''print 'Complete Update Statistics!'"
--刪除當(dāng)前數(shù)據(jù)庫(kù)所有表中的數(shù)據(jù)
sp_MSforeachtable @command1='Delete from ?'
sp_MSforeachtable @command1 = "TRUNCATE TABLE ?"
4.參數(shù)@whereand的用法:
@whereand參數(shù)在存儲(chǔ)過程中起到指令條件限制的作用圾叼,具體的寫法如下:
@whereend,可以這么寫 @whereand=' AND o.name in (''Table1'',''Table2'',.......)'
例如:我想更新Table1/Table2/Table3中NOTE列為NULL的值
sp_MSforeachtable @command1='Update ? Set NOTE='''' Where NOTE is NULL',@whereand=' AND o.name in (''Table1'',''Table2'',''Table3'')'
5."?"在存儲(chǔ)過程的特殊用法,造就了這兩個(gè)功能強(qiáng)大的存儲(chǔ)過程.
這里"?"的作用,相當(dāng)于DOS命令中、以及我們?cè)赪INDOWS下搜索文件時(shí)的通配符的作用捺癞。
6.小結(jié)
有了上面的分析,我們可以建立自己的sp_MSforeachObject:(轉(zhuǎn)貼)
USE MASTER
GO
CREATE proc sp_MSforeachObject
@objectType int=1,
@command1 nvarchar(2000),
@replacechar nchar(1) = N'?',
@command2 nvarchar(2000) = null,
@command3 nvarchar(2000) = null,
@whereand nvarchar(2000) = null,
@precommand nvarchar(2000) = null,
@postcommand nvarchar(2000) = null
as
/* This proc returns one or more rows for each table (optionally, matching @where), with each table 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 @mscat nvarchar(12)
select @mscat = ltrim(str(convert(int, 0x0002)))
if (@precommand is not null)
exec(@precommand)
/* Defined @isobject for save object type */
Declare @isobject varchar(256)
select @isobject= case @objectType when 1 then 'IsUserTable'
when 2 then 'IsView'
when 3 then 'IsTrigger'
when 4 then 'IsProcedure'
when 5 then 'IsDefault'
when 6 then 'IsForeignKey'
when 7 then 'IsScalarFunction'
when 8 then 'IsInlineFunction'
when 9 then 'IsPrimaryKey'
when 10 then 'IsExtendedProc'
when 11 then 'IsReplProc'
when 12 then 'IsRule'
end
/* Create the select */
/* Use @isobject variable isstead of IsUserTable string */
EXEC(N'declare hCForEach cursor global for select ''['' + REPLACE(user_name(uid), N'']'', N'']]'') + '']'' + ''.'' + ''['' +
REPLACE(object_name(id), N'']'', N'']]'') + '']'' from dbo.sysobjects o '
+ N' where OBJECTPROPERTY(o.id, N'''+@isobject+''') = 1 '+N' and o.category & ' + @mscat + N' = 0 '
+ @whereand)
declare @retval int
select @retval = @@error
if (@retval = 0)
exec @retval = sp_MSforeach_worker @command1, @replacechar, @command2, @command3
if (@retval = 0 and @postcommand is not null)
exec(@postcommand)
return @retval
GO
這樣我們來測(cè)試一下:
--獲得所有的存儲(chǔ)過程的腳本:
EXEc sp_MSforeachObject @command1="sp_helptext '?' ",@objectType=4
--獲得所有的視圖的腳本:
EXEc sp_MSforeachObject @command1="sp_helptext '?' ",@objectType=2
--比如在開發(fā)過程中,沒一個(gè)用戶都是自己的OBJECT OWNER,所以在真實(shí)的數(shù)據(jù)庫(kù)時(shí)都要改為DBO:
EXEc sp_MSforeachObject @command1="sp_changeobjectowner '?', 'dbo'",@objectType=1
EXEc sp_MSforeachObject @command1="sp_changeobjectowner '?', 'dbo'",@objectType=2
EXEc sp_MSforeachObject @command1="sp_changeobjectowner '?', 'dbo'",@objectType=3
EXEc sp_MSforeachObject @command1="sp_changeobjectowner '?', 'dbo'",@objectType=4
這樣就非常方便的將每一個(gè)數(shù)據(jù)庫(kù)對(duì)象改為DBO.
- 我個(gè)人的一個(gè)應(yīng)用:
sp_MSforeachdb 定期統(tǒng)計(jì)數(shù)據(jù)庫(kù)的空間分配情況:
create table master.dbo.dbsize (dbname sysname,checkTime VARCHAR(19),dbSize VARCHAR(50),logSize VARCHAR(50))
USE master
go
INSERT INTO master.dbo.dbsize ( dbName, checkTime, dbSize, logSize )
EXEC sp_msforeachdb 'select ''?'' dbName,CONVERT(VARCHAR(19),GETDATE(),120) checkTime,LTRIM(STR(SUM(CASE WHEN RIGHT(FILENAME,3)<>''ldf'' THEN convert (dec (15,2),size) * 8 / 1024 ELSE 0 END),15,2)+'' MB'') dbSize,
LTRIM(STR(SUM(CASE WHEN RIGHT(FILENAME,3)=''ldf'' THEN convert (dec (15,2),size) * 8 / 1024 ELSE 0 END),15,2)+'' MB'') logSize from ?.dbo.sysfiles'
--SELECT * FROM @insSize ORDER BY CONVERT(DECIMAL,LTRIM(RTRIM(SUBSTRING(dbSize,1,LEN(dbSize)-2)))) DESC
--需要時(shí)查詢?cè)摫砑纯?select * from master.dbo.dbsize;