Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

searching for linked server references Expand / Collapse
Author
Message
Posted Friday, February 6, 2009 9:06 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Wednesday, June 11, 2014 6:37 AM
Points: 34, Visits: 221
I would like to find all references to linked servers in stored procedures /functions/views. Ideally this would be done for all database on a server. We have a number hardcoded references (i.e. ServerA.NorthWind.dbo.Employees) and would perfer to use SQL aliases so we can migrate code easily.

The following code finds most references by searching for ".dbo." but it doesnt filter out commets. Does someone else have a better solution?

set quoted_identifier off
exec SP_MSFOREACHDB "
select '?' , name, sysobjects.xtype, SUBSTRING(TEXT,PATINDEX('%.dbo.%',TEXT) ,100)
from [?].dbo.sysobjects sysobjects join [?].dbo.syscomments syscomments on sysobjects.id = syscomments.id
where text like '%.dbo.%'"

Post #651770
Posted Friday, February 6, 2009 10:33 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 4:10 PM
Points: 12,909, Visits: 32,010
this is just a prototype for a single database, but it's easily adaptable i think.

I'm assuming that the current server has all the linked servers....so I thought why not search for the actual linked server name? ie "MACHINENAME\SQLEXPRESS" or whatever...to make it more specific, you could add a period to search for 'linkedserver.' instead of 'linkedserver'
It worked on a new proc i created just fine.
declare @LinkedServers table(
SRV_NAME varchar(128),
SRV_PROVIDERNAME varchar(128),
SRV_PRODUCT varchar(128),
SRV_DATASOURCE varchar(128),
SRV_PRIVIDERSTRING varchar(128),
SRV_LLOCATION varchar(128),
SRV_CAT varchar(128)
)
INSERT INTO @LinkedServers
EXEC sp_linkedservers
SELECT SRV_NAME FROM @LinkedServers

select *
from syscomments cross join @LinkedServers x
where charindex(x.SRV_NAME,syscomments.TEXT) > 1



Lowell

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #651840
Posted Friday, February 6, 2009 2:04 PM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Wednesday, June 11, 2014 6:37 AM
Points: 34, Visits: 221
Unfortunately I'm still on SQL 2000 so I get the following error:

Server: Msg 197, Level 15, State 1, Line 12
EXECUTE cannot be used as a source when inserting into a table variable.

Post #651981
Posted Friday, February 6, 2009 2:10 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 4:10 PM
Points: 12,909, Visits: 32,010
just change to a temp table, no problem:
CREATE TABLE #LinkedServers (
SRV_NAME varchar(128),
SRV_PROVIDERNAME varchar(128),
SRV_PRODUCT varchar(128),
SRV_DATASOURCE varchar(128),
SRV_PRIVIDERSTRING varchar(128),
SRV_LLOCATION varchar(128),
SRV_CAT varchar(128)
)
INSERT INTO #LinkedServers
EXEC sp_linkedservers
SELECT SRV_NAME FROM #LinkedServers

select *
from syscomments cross join #LinkedServers x
where charindex(x.SRV_NAME,syscomments.TEXT) > 1




Lowell

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #651984
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse