Home Microsoft SQL Server DigiMailing iRN Contact
    Keyword



sys.sp_addlinkedsrvlogin

 

Creates or updates a mapping between a login on the local instance of SQL Server and a security account on a remote server. This is a procedure in the mssqlsystemresource database. Disconfigured logins can result in "the error OLE DB provider 'SQLOLEDB' does not contain table" , "Login failed for user " and "There is no remote user".

Execution syntax
sp_addlinkedsrvlogin [ @rmtsrvname= ] 'rmtsrvname'
     [ , [ @useself= ] 'TRUE' | 'FALSE' | NULL ]
     [ , [ @locallogin= ] 'locallogin' ]
     [ , [ @rmtuser= ] 'rmtuser' ]
     [ , [ @rmtpassword= ] 'rmtpassword' ]

 

 

[ @rmtsrvname = ] 'rmtsrvname'
Is the name of a linked server that the login mapping applies to. So it's the name of you destination server. rmtsrvname is sysname, with no default.
[ @useself = ] 'TRUE' | 'FALSE' | NULL
Use the same password of a specified other one. Determines whether to connect to rmtsrvname by impersonating local logins or explicitly submitting a login and password. The data type is varchar(8), with a default of TRUE.
A value of TRUE specifies that logins use their own credentials to connect to rmtsrvname, with the rmtuser and rmtpassword arguments being ignored. FALSE specifies that the rmtuser and rmtpassword arguments are used to connect to rmtsrvname for the specified locallogin. If rmtuser and rmtpassword are also set to NULL, no login or password is used to connect to the linked server.
[ @locallogin = ] 'locallogin'
The SQL account that must be able to connect, is a login on the local server. locallogin is sysname, with a default of NULL. NULL specifies that this entry applies to all local logins that connect to rmtsrvname. If not NULL, locallogin can be a SQL Server login or a Windows login. The Windows login must have been granted access to SQL Server either directly, or through its membership in a Windows group granted access.
[ @rmtuser = ] 'rmtuser'
The user on the destination server, is the remote login used to connect to rmtsrvname when @useself is FALSE. When the remote server is an instance of SQL Server that does not use Windows Authentication, rmtuser is a SQL Server login. rmtuser is sysname, with a default of NULL.
[ @rmtpassword = ] 'rmtpassword'
The password on the destination server, is the password associated with rmtuser. rmtpassword is sysname, with a default of NULL.

 

 This procedure can also be used for quering Active Directory, here's a sample:

EXEC sp_addlinkedsrvlogin 'ADSI', false, 'Fabrikam\Administrator',
'CN=Administrator,OU=Sales,DC=activeds,DC=Fabrikam,DC=com', 'password'




Syntax
create procedure sys.sp_addlinkedsrvlogin
	@rmtsrvname		sysname,
	@useself		varchar(8) = 'true',
	@locallogin		sysname = NULL,
	@rmtuser		sysname = NULL,
	@rmtpassword	sysname = NULL
as
	declare	@pwd	varbinary(256),
			@localid		int,
			@useselfbit	bit,
			@ret	int

	-- DISALLOW USER TRANSACTION
	set implicit_transactions off
	if @@trancount > 0
	begin
		raiserror(15002,-1,-1,'sys.sp_addlinkedsrvlogin')
		return (1)
	end

	-- CHECK PERMISSIONS
	if not (has_perms_by_name(null, null, 'alter any login') = 1)
	begin
		EXEC %%System().AuditEvent(ID = 1380142156, Success = 0, TargetLoginName = @locallogin, TargetUserName = NULL, Role = NULL, Object = @rmtuser, Provider = NULL, Server = @rmtsrvname)
		raiserror(15247,-1,-1)
		return (1)
	end
		EXEC %%System().AuditEvent(ID = 1380142156, Success = 1, TargetLoginName = @locallogin, TargetUserName = NULL, Role = NULL, Object = @rmtuser, Provider = NULL, Server = @rmtsrvname)


	-- VALIDATE @useself PARAMETER 
	-- IF @useself IS TRUE IT OVERRIDES PARAMETERS @rmtuser and @rmtpassword
	select @useself = lower(@useself), @useselfbit = CASE WHEN lower(@useself) = 'true' THEN 1 ELSE 0 END
	if @useself is null or @useself not in ('true','false')
	begin
		raiserror(15600,-1,-1,'sys.sp_addlinkedsrvlogin')
		return 1
	end
	if @useselfbit = 1
		select @rmtuser = NULL, @rmtpassword = NULL

	BEGIN TRAN

	-- VALIDATE/LOCK SERVER NAME 
	EXEC %%LinkedServer ( Name = @rmtsrvname ) . Lock ( Exclusive = 1 )
	IF @@ERROR <> 0
	begin
		ROLLBACK TRAN
		raiserror(15015,-1,-1,@rmtsrvname)
		return (1)
	end

	-- IF SPECIFIED CHECK LOCAL USER NAME (NO NT GROUP!)
	select @localid = 0
	if (@locallogin IS NOT NULL)
	begin
		-- share-lock the local login
		EXEC %%LocalLogin ( Name = @locallogin ) . Lock ( Exclusive = 0 )
		IF @@ERROR = 0
			select @localid = principal_id from sys.server_principals
				where name = @locallogin and type in ('S', 'U')
		else
		begin
			-- ADD ROW FOR NT USER LOGIN IF NEEDED 
			if (get_sid('\U'+@locallogin) IS NOT NULL)
			begin
				EXEC @ret = sys.sp_MSaddlogin_implicit_ntlogin @locallogin
				if (@ret = 0)
					select @localid = principal_id from sys.server_principals
						where name = @locallogin and type = 'U'
			end
		end
		if (@localid = 0)
		begin
			ROLLBACK TRAN
			raiserror(15007,-1,-1,@locallogin)
			return (1)
		end
	end

	-- IF MAPPING ALREADY EXISTS FOR THIS SID, REMOVE IT (compatibility) 
	IF EXISTS (SELECT * FROM sys.linked_logins WHERE
			server_id IN (SELECT server_id FROM sys.servers where name = @rmtsrvname)
			AND local_principal_id = @localid)
	BEGIN
		EXEC %%LinkedServer(Name=@rmtsrvname).RemoveLinkedLogin(LocalID=@localid)
	END

	-- ADD THE SPECIFIED MAPPING 
	SELECT @pwd = convert(varbinary(256), @rmtpassword)
	EXEC %%LinkedServer(Name=@rmtsrvname).NewLinkedLogin(
				LocalID=@localid, UseSelf=@useselfbit, RemoteName=@rmtuser, Password=@pwd)

	-- SHOULDN'T GET A DUPLICATE (JUST DROPPED IF THERE), BUT DO THIS AS AN ASSERT 
	IF @@ERROR <> 0
	BEGIN
		ROLLBACK TRAN
		raiserror(15185,-1,-1,@rmtuser,@locallogin,@rmtsrvname)
		return (1)
	END

	-- EMDEventType(x_eet_Create_Linked_Server_Login), EMDUniversalClass(x_eunc_Linked_Server), src major id, src minor id, src name
	-- -1 means ignore target stuff, target major id, target minor id, target name,
	-- # of parameters, 5 parameters
	-- Note: we do not pass @rmtpassword since it contains a password
	EXEC %%System().FireTrigger(ID = 226, ID = 102, ID = 0, ID = 0, Value = @rmtsrvname,
		ID = 101, ID = @localid, ID = 0, Value = NULL,
		ID = 5, Value = @rmtsrvname, Value = @useself, Value = @locallogin, Value = @rmtuser, Value = NULL, Value = NULL, Value = NULL)

	-- SUCCESS 
	COMMIT TRAN
	return(0) -- sp_addlinkedsrvlogin

 
Last revision 2008RTM
See also

  sp_adddistributor (Procedure)
sp_changedistributor_password (Procedure)
sp_MSchangerepllinkedsrvrpassword (Procedure)
sp_MSprocesslogshipmonitorlink (Procedure)
sp_MSprocesspublisherlink (Procedure)
sp_MSrepl_adddistpublisher (Procedure)
sp_MSrepl_testadminconnection (Procedure)
sp_vupgrade_heterogeneous_publishers (Procedure)
       



News

  Query a named instance
Sybase+ASE+silent+install
SQL 2008 R2
Deprecated procedures in SQL2008
Reporting Services item-level role definitions
Create all your missing indexes
Converting datetime field
Start MSSQL Server Profiler at time
Replicating MSSQL Server views
Exploring Microsoft Sharepoint
The OLE DB provider "SQLNCLI10" for linked server indicates.
Mobile solar charger
Oracle to SQL Server replication
Cannot insert the value NULL into column
Undocumented Microsoft SQL Server 2008
VMware
Zoekmachine optimalisatie
SQL Servers hidden objects
FckEditor
Flash in Ajax
De hype die AJAX heet
Barcode scannen
MySQL; Gratis, makkelijk en snel!
PHP
sIFR; de combinatie tussen HTML en Flash