March 26, 2018 at 8:35 am
Can anyone tell me why this is not working (I obfuscated the password, BTW). I am sysadmin on the server ('sentara\dxthomas'). If I remove the "Execute As" and execute the SP everything works fine. If I include it, the error I get is:
Msg 15247, Level 16, State 1, Procedure sp_MSaddserver_internal, Line 34
User does not have permission to perform this action.
Msg 15247, Level 16, State 1, Procedure sp_addlinkedsrvlogin, Line 25
User does not have permission to perform this action.
Alter Procedure [dbo].[RemoteLink]
@LinkedServerName Varchar(50)
--With Encryption
With Execute As 'sentara\dxthomas'
As
Set NoCount On
Declare @ValidServer bit = 0
Declare @CurrentUser Varchar(50) = system_user
If @LinkedServerName='CLARITYANCETTA'
Set @ValidServer = 1
If Not Exists (Select 1 From sysservers Where srvname = 'CLARITYANCETTA' )
Begin
EXEC master.dbo.sp_addlinkedserver @server = N'CLARITYANCETTA', @srvproduct=N'SQLSERVER', @provider=N'SQLNCLI', @datasrc=N'CLARITYANCETTA', @catalog=N'HETS';
EXEC master.dbo.sp_addlinkedsrvlogin @rmtsrvname=N'CLARITYANCETTA',@useself=N'False',@locallogin=NULL,@rmtuser=N'HetsUser',@rmtpassword='xxxx';
End
March 26, 2018 at 10:54 am
What database is this stored proc in? If this is not in MASTER, then you need to sign the stored proc with a certificate to be able to use EXECUTE AS across multiple databases.
https://docs.microsoft.com/en-us/sql/relational-databases/tutorial-signing-stored-procedures-with-a-certificate
March 26, 2018 at 11:42 am
Chris Harshman - Monday, March 26, 2018 10:54 AMWhat database is this stored proc in? If this is not in MASTER, then you need to sign the stored proc with a certificate to be able to use EXECUTE AS across multiple databases.
https://docs.microsoft.com/en-us/sql/relational-databases/tutorial-signing-stored-procedures-with-a-certificate
I just created the SP in Master, switched my context to Master, and got the same error. If I remove the Execute As, the proc executes as expected.
March 26, 2018 at 12:03 pm
Try specifying a login - something like:
Alter Procedure [dbo].[RemoteLink]
@LinkedServerName Varchar(50)
AS
--With Encryption
Execute As login = 'Domain\Account'
Sue
March 26, 2018 at 3:40 pm
Dave Thomas - Monday, March 26, 2018 8:35 AMCan anyone tell me why this is not working (I obfuscated the password, BTW). I am sysadmin on the server ('sentara\dxthomas'). If I remove the "Execute As" and execute the SP everything works fine. If I include it, the error I get is:Msg 15247, Level 16, State 1, Procedure sp_MSaddserver_internal, Line 34
User does not have permission to perform this action.
Msg 15247, Level 16, State 1, Procedure sp_addlinkedsrvlogin, Line 25
User does not have permission to perform this action.
Alter Procedure [dbo].[RemoteLink]@LinkedServerName Varchar(50)
--With Encryption
With Execute As 'sentara\dxthomas'
As
Set NoCount On
Declare @ValidServer bit = 0
Declare @CurrentUser Varchar(50) = system_user
If @LinkedServerName='CLARITYANCETTA'
Set @ValidServer = 1
If Not Exists (Select 1 From sysservers Where srvname = 'CLARITYANCETTA' )
Begin
EXEC master.dbo.sp_addlinkedserver @server = N'CLARITYANCETTA', @srvproduct=N'SQLSERVER', @provider=N'SQLNCLI', @datasrc=N'CLARITYANCETTA', @catalog=N'HETS';
EXEC master.dbo.sp_addlinkedsrvlogin @rmtsrvname=N'CLARITYANCETTA',@useself=N'False',@locallogin=NULL,@rmtuser=N'HetsUser',@rmtpassword='xxxx';
End
The correct syntax is
EXECUTE AS LOGIN = 'loginnamehere'
--Jeff Moden
Change is inevitable... Change for the better is not.
March 26, 2018 at 7:36 pm
Sue_H - Monday, March 26, 2018 12:03 PMTry specifying a login - something like:
Alter Procedure [dbo].[RemoteLink]
@LinkedServerName Varchar(50)
AS
--With Encryption
Execute As login = 'Domain\Account'
Sue
Sorry, Sue. Didn't see that you also posted on the correct syntax.
--Jeff Moden
Change is inevitable... Change for the better is not.
March 27, 2018 at 1:28 am
When you as a sysadmin create / alter a procedure on a user database it's saved as created by user 'dbo' of that database.
When you execute that procedure the code is executed in the context of used 'dbo' of that database, not the login you used to create it.
To allow that procedure to do things on the server you need to make the database it's saved in "trusted".
Them 'dbo' user of that database will have sysadmin privileges on the server.
P.S. Master database is not necessarily "trusted".
_____________
Code for TallyGenerator
March 27, 2018 at 11:31 am
Sue_H - Monday, March 26, 2018 12:03 PMTry specifying a login - something like:
Alter Procedure [dbo].[RemoteLink]
@LinkedServerName Varchar(50)
AS
--With Encryption
Execute As login = 'Domain\Account'
Sue
This works, but the only people that can impersonate the login with the proper privileges are already sysadmin.
March 27, 2018 at 11:35 am
Sergiy - Tuesday, March 27, 2018 1:28 AMWhen you as a sysadmin create / alter a procedure on a user database it's saved as created by user 'dbo' of that database.When you execute that procedure the code is executed in the context of used 'dbo' of that database, not the login you used to create it.To allow that procedure to do things on the server you need to make the database it's saved in "trusted".Them 'dbo' user of that database will have sysadmin privileges on the server.P.S. Master database is not necessarily "trusted".
When you say "trusted" do you mean "trustworthy"?
March 27, 2018 at 12:10 pm
Solution!
When using
With Execute As
In a stored procedure, the database that the stored procedure is created in must be set to "Trustworthy = On"
Thanks to everyone for their help!
BTW, this whole effort is to allow users to create temporary linked servers that magically "dissappear" after they follow the "RemoteLink" sp with a query. Had to do it this way because LAN group has a bad time with SPN delegation and kerberose configuration.
March 27, 2018 at 1:28 pm
Somehow I don't think that setting the database to trustworthy is really the long term solution you're looking for. There are lots of articles that talk about the security problems with this:
https://www.google.com/search?q=sql+server+trustworthy+security+risk&oq=sql+server+trustworthy+&aqs=chrome.2.69i57j0l5.8006j0j8&sourceid=chrome&ie=UTF-8
Viewing 11 posts - 1 through 10 (of 10 total)
You must be logged in to reply to this topic. Login to reply