Find all Procedures, Views, Functions that have been renamed
We have had a standard practice of using sp_rename on procedures when moving code for years. This is now causing issues when we want to automate some processes of scripting in/out certain objects.
This will return database, object id, object name, and the first 50 of syscomments where the object name is not found in the 1st block of syscomments. It's ugly and a kludge but it works. Anyone care to expand on it is more than welcome. I need to add a block for triggers as well as they are defined in syscomments to, but we hardly use them, and doubt we would rename one.
With the list, you can then recreate them with the proper names either via scripting, or SSMS enterprise manager. I just drop them, as they are 99.9% obsolete objects.
http://support.microsoft.com/kb/243198
Quote from BOL:
Renaming a stored procedure, view or trigger will not change the name of the corresponding object name in the syscomments table. This may result in problems generating a script for the object as the old name
will be inserted from the syscomments table into the CREATE statement. For best results, do not rename these object types. Instead, drop and re-create the object by its new name.
select
db_name() as DbName,
id,
ObjName,
xtype,
substring(txt,beg,50) as txt
into #temp
from (
select
so.id,
so.xtype,
ltrim(rtrim(cast([name] as varchar(100)))) as ObjName,
charindex('createproc',ltrim(replace(replace(replace(sc.[text],' ',''),char(10),''), char(13),''))) as beg,
ltrim(replace(replace(replace(sc.[text],' ',''),char(10),''), char(13),'')) as txt,
charindex(ltrim(rtrim(cast([name] as varchar(100)))),replace(sc.[text],' ','')) as idx
from sysobjects so
inner join syscomments sc on so.id=sc.id
where
so.xtype in ('P','F','V')
and
OBJECTPROPERTY(so.id, N'IsMsShipped') = 0
and
sc.colid=1
) a
where 1=2
exec sp_msforeachdb '
use [?];
insert into #temp
select
db_name() as DbName,
id,
ObjName,
xtype,
substring(txt,beg,50) as txt
from (
select
so.id,
so.xtype,
ltrim(rtrim(cast([name] as varchar(100)))) as ObjName,
charindex(''createproc'',ltrim(replace(replace(replace(sc.[text],'' '',''''),char(10),''''), char(13),''''))) as beg,
ltrim(replace(replace(replace(sc.[text],'' '',''''),char(10),''''), char(13),'''')) as txt,
charindex(ltrim(rtrim(cast([name] as varchar(100)))),replace(sc.[text],'' '','''')) as idx
from sysobjects so
inner join syscomments sc on so.id=sc.id
where
so.xtype =''P''
and
OBJECTPROPERTY(so.id, N''IsMsShipped'') = 0
and
OBJECTPROPERTY(so.id, N''IsEncrypted'') = 0
and
sc.colid=1
) a
where idx=0
order by objname
'
exec sp_msforeachdb '
use [?];
insert into #temp
select
db_name() as DbName,
id,
ObjName,
xtype,
substring(txt,beg,50) as txt
from (
select
so.id,
so.xtype,
ltrim(rtrim(cast([name] as varchar(100)))) as ObjName,
charindex(''createview'',ltrim(replace(replace(replace(sc.[text],'' '',''''),char(10),''''), char(13),''''))) as beg,
ltrim(replace(replace(replace(sc.[text],'' '',''''),char(10),''''), char(13),'''')) as txt,
charindex(ltrim(rtrim(cast([name] as varchar(100)))),replace(sc.[text],'' '','''')) as idx
from sysobjects so
inner join syscomments sc on so.id=sc.id
where
so.xtype =''V''
and
OBJECTPROPERTY(so.id, N''IsMsShipped'') = 0
and
OBJECTPROPERTY(so.id, N''IsEncrypted'') = 0
and
sc.colid=1
) a
where idx=0
order by objname
'
exec sp_msforeachdb '
use [?];
insert into #temp
select
db_name() as DbName,
id,
ObjName,
xtype,
substring(txt,beg,50) as txt
from (
select
so.id,
so.xtype,
ltrim(rtrim(cast([name] as varchar(100)))) as ObjName,
charindex(''createfunc'',ltrim(replace(replace(replace(sc.[text],'' '',''''),char(10),''''), char(13),''''))) as beg,
ltrim(replace(replace(replace(sc.[text],'' '',''''),char(10),''''), char(13),'''')) as txt,
charindex(ltrim(rtrim(cast([name] as varchar(100)))),replace(sc.[text],'' '','''')) as idx
from sysobjects so
inner join syscomments sc on so.id=sc.id
where
so.xtype =''F''
and
OBJECTPROPERTY(so.id, N''IsMsShipped'') = 0
and
OBJECTPROPERTY(so.id, N''IsEncrypted'') = 0
and
sc.colid=1
) a
where idx=0
order by objname
'
select * from #temp
where dbname<>'tempdb'
drop table #temp