浅析sql server一个没有公开的存储过程
从sqlserver6.5开始,ms提供了一个非常有用的系统存储过程sp_msforeachtable和sp_msforeachdb;作为dba会经常需要检查所有的数据库或用户表,比如:检查所有数据库的容量;看看指定数据库所有用户表的容量,所有表的记录数…,我们一般处理这样的问题都是用游标分别处理处理,比如:在数据库检索效率非常慢时,我们想检查数据库所有的用户表,我们就必须这样写游标:
declare @tablename varchar(255)
declare @exesql varchar(4000)
declare table_cursor cursor for select [name] from sysobjects where xtype=u
open table_cursor
fetch next from table_cursor into @tablename
while(@@fetch_status=0)
begin
print @tablename
select @exesql=dbcc checktable(+@tablename+)
exec(@exesql)
fetch next from table_cursor into @tablename
end
close table_cursor
deallocate table_cursor
go
如果我们用sp_msforeachtable就可以非常方便的达到相同的目的:
exec sp_msforeachtable @command1=”print ? dbcc checktable(?)”
大家可以看出这样就更加简洁(虽然在后台也是通过游标来处理的),下面我们就仔细分析一下sp_msforeachtable这个存储过程:
我们看看sp_msforeachtable详细的code:
use master
go
sp_helptext sp_msforeachtable
–下面时sp_msforeachtable的原始代码
create proc sp_msforeachtable
@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 wont 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)
/* create the select */
exec(ndeclare 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, nisusertable) = 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
这个系统存储过程有7个参数:
@command1 nvarchar(2000), –第一条运行的t-sql指令
@replacechar nchar(1) = n?, –指定的占位符号
@command2 nvarchar(2000) = null,–第二条运行的t-sql指令
@command3 nvarchar(2000) = null, –第三条运行的t-sql指令
@whereand nvarchar(2000) = null, –可选条件来选择表
@precommand nvarchar(2000) = null, –在表前执行的指令
@postcommand nvarchar(2000) = null –在表后执行的指令
所以上面的语句也可以这样写:
exec sp_msforeachtable @command1=”print ?”,
@command2= “dbcc checktable(?)”
了解参数以后,就让我们做几个实列吧:
1.获得每个表的记录数和容量:
exec sp_msforeachtable @command1=”print ?”,
@command2=”sp_spaceused ?”,
@command3= “select count(*) from ? “
2.更新pubs数据库中已t开头的所有表的统计:
exec sp_msforeachtable @whereand=”and name like t%”,
@replacechar=*,
@precommand=”print updating statistics….. print “,
@command1=”print * update statistics * “,
@postcommand= “printprint complete update statistics!”
sp_msforeachdb除了@whereand外,和sp_msforeachtable的参数是一样的,我们可以通过这个存储过程检测所有的数据库,比如:
1.检查所有的数据库
exec sp_msforeachdb @command1=”print ?”,
@command2=”dbcc checkdb (?) “
有了上面的分析,我们可以建立自己的sp_msforeachobject:
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 wont 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(ndeclare 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
这样我们来测试一下:
1.获得所有的存储过程的脚本:
exec sp_msforeachobject @command1=”sp_helptext ? “,@objecttype=4
2.获得所有的视图的脚本:
exec sp_msforeachobject @command1=”sp_helptext ? “,@objecttype=2
3.比如在开发过程中,没一个用户都是自己的object owner,所以在真实的数据库时都要改为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
这样就非常方便的将每一个数据库对象改为dbo.
当然还要很多非常好的功能,大家可以自己深入研究吧:-)
