SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


searching for linked server references


searching for linked server references

Author
Message
paul Arscott
paul Arscott
Valued Member
Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)

Group: General Forum Members
Points: 70 Visits: 238
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.%'"


Lowell
Lowell
SSC-Dedicated
SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)

Group: General Forum Members
Points: 37207 Visits: 40280
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

--
help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

paul Arscott
paul Arscott
Valued Member
Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)

Group: General Forum Members
Points: 70 Visits: 238
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.


Lowell
Lowell
SSC-Dedicated
SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)

Group: General Forum Members
Points: 37207 Visits: 40280
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

--
help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search