Linked servers

  • I would like to create a linked server with the name "Production" that points to an IP address&port of an server instance. I want to do this so I can refer to [Production] in all my queries so that when the IP&Port of "Production" changes all the queries keep working. It looks like all I can do is create a linked server with the name IP address&port. This causes the head-ache of needing to update every query when the server changes. Am I missing something or is there no way to abstract a linked server?

    <><
    Livin' down on the cube farm. Left, left, then a right.

  • USE [master]

    GO

    EXEC sys.sp_addlinkedserver

    @server = N'Production',

    @srvproduct = N'',

    @provider = N'SQLNCLI',

    @datasrc = N'127.0.0.1,1713'; -- fix this up for your IP and port

    Then you can drop and recreate it as needed:

    USE [master]

    GO

    EXEC master.dbo.sp_dropserver

    @server = N'Production',

    @droplogins = 'droplogins';

    GO

    There are no special teachers of virtue, because virtue is taught by the whole community.
    --Plato

  • You could also just fix the port number of your production instance.

    It shouldn't change that much, unless someone just didn't pay attention to the port number the installed the instance.

    Must be a heck of an issue for your FW-admins too.

    I'm always very wary when someone request a linked server definition.

    Untangling issues on both involved servers ( or more, in case of join with extra linked server queries )

    often takes way to long.

    Another thing people often forget is the difference in maintenance windows for linked server involved instances.

    Queries and apps not working because of linked server maintenance windows aren't considered an issue until they happen.

    I hope you've got your environment under control.

    Johan

    Learn to play, play to learn !

    Dont drive faster than your guardian angel can fly ...
    but keeping both feet on the ground wont get you anywhere :w00t:

    - How to post Performance Problems
    - How to post data/code to get the best help[/url]

    - How to prevent a sore throat after hours of presenting ppt

    press F1 for solution, press shift+F1 for urgent solution 😀

    Need a bit of Powershell? How about this

    Who am I ? Sometimes this is me but most of the time this is me

  • Thanks to both of you.

    Unfortunately I/we have virtually no control over the choices being made. 🙁

    <><
    Livin' down on the cube farm. Left, left, then a right.

  • Looking into to this more I do have a question:

    So to add a linked server you use sp_addlinkedserver and to delete it you use sp_dropserver?

    sp_addserver is unrelated?

    Is it possible to alter a linked server, i.e. change what it points to, or do you just drop and create again?

    <><
    Livin' down on the cube farm. Left, left, then a right.

  • Tobar (4/10/2013)


    Looking into to this more I do have a question:

    So to add a linked server you use sp_addlinkedserver and to delete it you use sp_dropserver?

    Not a great naming convention on someone's part, but yes.

    sp_addserver is unrelated?

    You won't need to call sp_addserver directly for Linked Server creation. sys.sp_addlinkedserver actually calls an internal version of sp_addserver called sys.sp_MSaddserver_internal and you will see a new entry in sys.servers after you create a new Linked Server with sys.sp_addlinkedserver.

    Is it possible to alter a linked server, i.e. change what it points to, or do you just drop and create again?

    I don't see a way to modify where it is pointing, just some of the options.

    You can always check for existence before dropping it:

    USE [master]

    GO

    IF EXISTS ( SELECT *

    FROM sys.servers

    WHERE name = N'Production' )

    EXEC dbo.sp_dropserver

    @server = N'Production',

    @droplogins = 'droplogins';

    GO

    There are no special teachers of virtue, because virtue is taught by the whole community.
    --Plato

  • Thanks again.

    <><
    Livin' down on the cube farm. Left, left, then a right.

Viewing 7 posts - 1 through 6 (of 6 total)

You must be logged in to reply to this topic. Login to reply