@@SERVERNAME is NULL & SQL Server Replication

Issuing the following query should return the server name of the instance you are working with. In the scenario that is about to be described, the server had some work done on it which left the query below returning NULL.

This causes problems when attempting to run tools such as the replication monitors and wizards as they appear to use this query internally and thus complain that a connection cannot be made to a (NULL) server during the login process. Also various other errors start occurring using Server Management Studio.

SELECT @@SERVERNAME

As the sever had been used for replication in the past, there was a node under linked servers for itself. The server was acting as its own distributor in replication, thus had a “replication” database under System Databases node in Management Studio.

There was also a Linked Server named repl_distributor that I take to be a pointer to the distributor, in this case the same server.

The problem was the the Repliation >> Local Publications node contained a publication that was not working.

Trying to run any commands resulted in the server complaining about the null server name, by the way the following command returned the correct server name;

SELECT SERVERPROPERTY('MachineName'), SERVERPROPERTY ('InstanceName')

It seems this is held more up to date than the other property and syncs with the sever name better.

Change @@SERVERNAME

All the server names “registered” can be viewed with

sp_helpserver

In the returned table it was possible to see the Linked server, but there was no server with the ID column of 0. The row with the ID column of 0 is the server name returned when the @@SERVERNAME property is used. To set this add a server with the following;

sp_addserver '','local'

The local parameter tells it that you are talking about this special server name. However attempting this in this case resulted in the server complaining that the server already existed, due to the LINKED server.

It should be possible to drop the existing linked server by issuing the following command;

SP_DROPSERVER '','droplogins'

This didn’t work as it complained that the server was acting as a publisher. Argh!

Temporary Change to @@SERVERNAME

In order to “getinto” the SQL tools I creating a ficticous servername, adding that servername to the local hosts file of the server.

sp_addserver 'TEMP','local'

In the hosts file C:\WINDOWS\system32\drivers\etc\hosts

127.0.0.1 localhost
127.0.0.1 TEMP

YOU MUST restart the SQL server service for the @@SERVERNAME variable to refresh, easy to forget!

So now @@SERVERNAME returned a false servername, however at least working on the server I could use Management Studio to connect to the server under this fake name and start accessing normal tools for replication.

Removing replication

At this point the aim was to totally remove replication and then add it all back in once it was all gone. To do this there is a guidance document How to manually remove a replication in SQL Server 2000 or in SQL Server 2005this seemed to work for 2008 too.

For each replicated database, this was used to rip out all replication from the databases.

exec master.dbo.sp_removedbreplication '

sp_dropdistributor @no_checks=1, @ignore_distributor=1

The rest of the commands in this section are a medley of commands that can be used to get to the point where the replication is gone.

To drop the replication distribution database use this;

alter database distribution set offlinedrop database distribution

master.dbo.sp_serveroption @server=N'', @optname=N'dist', @optvalue =N'false'

Helpful help functions the last two seemed to be the final step needed in this case to allow the dropping of the various objects (linked server and replication database).

    sp_msrepl_check_server
    sp_helpdistpublishersp_get_distributor
    sp_helpdistributorsp_helppublication
    select * from msdb..msdistpublishersdelete from msdb..msdistpublishers

“There are still remote logins or linked logins for the server” - one biggest breakthrough with all this was the clue to try right clicking on the object you are trying to destroy, scripting it and then using that to get the server names for the above manually removing replication method and the other commands listed. It also gives you the scaffold to change the option values to false for the linked servers. See the following fragment that I hacked to get our options for replication and publication set to false after using the scripting technique.

/****** Object:  LinkedServer [<YourLinkedServerName>]    Script Date: 02/18/2011 02:43:09 ******/
EXEC master.dbo.sp_addlinkedserver @server = N'<YourLinkedServerName>', @srvproduct=N'SQL Server'
 /* For security reasons the linked server remote logins password is changed with ######## */
EXEC master.dbo.sp_droplinkedsrvlogin @rmtsrvname=N'<YourLinkedServerName>',@locallogin=NULL 

  @useself=N'False',@locallogin=NULL,@rmtuser=N'webreplication',@rmtpassword='########'
EXEC master.dbo.sp_droplinkedsrvlogin @rmtsrvname=N'<YourLinkedServerName>',@locallogin=NULL 

 @useself=N'False',,@locallogin=NULL,@rmtuser=N'webreplication',@rmtpassword='########'
EXEC master.dbo.sp_serveroption @server=N'<YourLinkedServerName>', @optname=N'dist',

 @optvalue=N'false'
GO
EXEC master.dbo.sp_serveroption @server=N'<YourLinkedServerName>', @optname=N'data access',

 @optvalue=N'true'
GO
EXEC master.dbo.sp_serveroption @server=N'<YourLinkedServerName>', @optname=N'sub', @optvalue=

N'false'
GO
EXEC master.dbo.sp_serveroption @server=N'<YourLinkedServerName>', @optname=N'pub', @optvalue=

N'false'

Changing @@SERVERNAME to what it should be

Now it was possible to change the servername back to what is should have been in the first place, and remember to delete the entry in the hosts file.

SP_DROPSERVER 'TEMP','droplogins'sp_addserver ','local'

YOU MUST restart the SQL server service for the @@SERVERNAME variable to refresh, easy to forget!

sp_helpserver

Looking and help server should now return the server names with the actual servername having an ID of 0.

SQL Jobs

Don’t forget to delete all the sql replication jobs and agent jobs.

Thus after a few hours the server now has no replication and it is possible to start again.