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


Stored Procedures Execute Permissions


Stored Procedures Execute Permissions

Author
Message
Dree Vasquez
Dree Vasquez
Valued Member
Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)

Group: General Forum Members
Points: 64 Visits: 208
My global office programmed all our stored procedures and it contains a lot of create/delete temp tables, truncate tables, update, insert etc.

When I grant a user the rights to execute stored procedures, the user cannot execute these stored procedures because of insufficient permissions. A lot of the stored procedures seem to require that a user executing them not only require Execute stored procedures permissions, but also ended up having db_owner rights.

Is there a way I can control this, please? I do not wish to grant these users the rights to UPDATE, INSERT, DELETE rows, create or delete tables, alter schema rights or even db_owner rights. But it seems to be hard, because they cannot execute the procedures without these.

Is there any suggestions on how I can do this, please? Even adding EXECUTE AS in the stored procedures don't work.

Is there other tools I can use that allows the users to execute stored procedures as an SA, but with logging so that I can review who ran all these stored procedures. Will Control-M or Dollar Universe able to do such things?

Thank you.
GilaMonster
GilaMonster
SSC Guru
SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)

Group: General Forum Members
Points: 224723 Visits: 46321
Without seeing the code, this is a guess....

If the user has exec rights on the procedure and the procedure is owned by the same principal as the tables, the user won't need update, insert or anything like that because of ownership chaining. Creating and dropping temp tables requires no permissions. Truncate table is likely the culprit (if done on a user table, not a temp table). Can you change that to delete instead?

Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


Dree Vasquez
Dree Vasquez
Valued Member
Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)

Group: General Forum Members
Points: 64 Visits: 208
Hi,

What you mean by the the same principal? Is it dbo?

I cannot modify the stored procedures but I do see truncate table statements in there. When I grant the user db_datareader, db_datawriter and Alter Schema rights, users are creating tables and leaving the tables inside there even though they should drop it. This is a problem for us.

Is there another way I can grant execute permissions without all these rights, just execute and db_datareader?
GilaMonster
GilaMonster
SSC Guru
SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)

Group: General Forum Members
Points: 224723 Visits: 46321
Dree Vasquez (4/14/2013)
What you mean by the the same principal? Is it dbo?


Could be dbo, could be another database principal (owner, not schema)

I cannot modify the stored procedures but I do see truncate table statements in there. When I grant the user db_datareader, db_datawriter and Alter Schema rights, users are creating tables and leaving the tables inside there even though they should drop it. This is a problem for us.


Creating and dropping user tables inside a procedure? That will be a problem, not to mention being a rather bad practice.

Is there another way I can grant execute permissions without all these rights, just execute and db_datareader?


Again, without seeing the code, I'm guessing. Ownership chaining will mean that you don't need to grant data reader and data writer.

Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


Eric M Russell
Eric M Russell
One Orange Chip
One Orange Chip (29K reputation)One Orange Chip (29K reputation)One Orange Chip (29K reputation)One Orange Chip (29K reputation)One Orange Chip (29K reputation)One Orange Chip (29K reputation)One Orange Chip (29K reputation)One Orange Chip (29K reputation)

Group: General Forum Members
Points: 29052 Visits: 11514
In the example below, I've created a stored procedure called [acct_staging_truncate] which truncates a table. The user 'acctmaint' is db_owner, and user 'JoeSchmo' is a public member with no permissions except execution on the procedure [acct_staging_truncate].

create procedure acct_staging_truncate
with execute as 'acctmaint'
as
truncate table acct_staging;
go

grant exec on acct_staging_truncate to JoeSchmo;
go


I've confirmed that JoeSchmo can execute the procedure successfully, but he can't truncate, select, or anything else directly on the table.


"The universe is complicated and for the most part beyond your control, but your life is only as complicated as you choose it to be."
Orlando Colamatteo
Orlando Colamatteo
SSC-Dedicated
SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)

Group: General Forum Members
Points: 39690 Visits: 14412
WITH EXECUTE AS can fall down if there are cross-database calls.

To answer your question, yes, there is a way to setup your database security such that the Database User only has EXECUTE permissions on the stored procedure and no direct permissions to the underlying objects that procedure accesses. As for how to achieve that, it will depend on what the proc does. If you can post the code we can better assist. It could be as simple as changing TRUNCATE to DELETE if all objects are in the same database and owned by the same Database Principal, in which case Ownership Chaining will cover the necessary scenarios. If changing code is not an option and WITH EXECUTE AS will not work due to corss-database calls then you can look into impersonation or certificate signing.

__________________________________________________________________________________________________
There are no special teachers of virtue, because virtue is taught by the whole community. --Plato
Dree Vasquez
Dree Vasquez
Valued Member
Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)

Group: General Forum Members
Points: 64 Visits: 208
Hi All

Thanks so much for all the suggestions. I really appreciate it.

I asked the Global developer and they said their procedures cannot be changed. And they also said that we should not limit the rights of the Developers/App Support Team to the databases. In my office, the developer and app support are the same team and I don't think it is correct to grant everyone db_owner privileges.

Do we really give developers the rights to execute stored procedures on the Test and the Production Systems. (In my office, Change Management is required on the Test and Production Systems) and granting such privileges will mean no one needs to raise an CR in the first place.
GilaMonster
GilaMonster
SSC Guru
SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)SSC Guru (224K reputation)

Group: General Forum Members
Points: 224723 Visits: 46321
Dree Vasquez (4/18/2013)
I don't think it is correct to grant everyone db_owner privileges.


No, absolutely not. Principal of minimal privileged. Users don't need to be able to drop the database, delete all tables, change settings, backup, restore and hence they should not have enough permissions to do that.

Regarding your permissions problems, check the ownership of the tables and the procedures (not schema, owner), see if they are different. If they are, then the ownership chaining mentioned earlier won't work and hence the users will be having permission denied errors.

Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


Eric M Russell
Eric M Russell
One Orange Chip
One Orange Chip (29K reputation)One Orange Chip (29K reputation)One Orange Chip (29K reputation)One Orange Chip (29K reputation)One Orange Chip (29K reputation)One Orange Chip (29K reputation)One Orange Chip (29K reputation)One Orange Chip (29K reputation)

Group: General Forum Members
Points: 29052 Visits: 11514
Dree Vasquez (4/18/2013)
Hi All

Thanks so much for all the suggestions. I really appreciate it.

I asked the Global developer and they said their procedures cannot be changed. And they also said that we should not limit the rights of the Developers/App Support Team to the databases. In my office, the developer and app support are the same team and I don't think it is correct to grant everyone db_owner privileges.

Do we really give developers the rights to execute stored procedures on the Test and the Production Systems. (In my office, Change Management is required on the Test and Production Systems) and granting such privileges will mean no one needs to raise an CR in the first place.

If you're a member of sysadmin, then you can grant or deny whatever privillages you know are really required. You can even edit and recompile the stored procedures too. Don't let some 3rd party tell you how to manage your database.


"The universe is complicated and for the most part beyond your control, but your life is only as complicated as you choose it to be."
crmitchell
crmitchell
Ten Centuries
Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)

Group: General Forum Members
Points: 1260 Visits: 1793
Eric M Russell (4/18/2013)
Dree Vasquez (4/18/2013)
Hi All

Thanks so much for all the suggestions. I really appreciate it.

I asked the Global developer and they said their procedures cannot be changed. And they also said that we should not limit the rights of the Developers/App Support Team to the databases. In my office, the developer and app support are the same team and I don't think it is correct to grant everyone db_owner privileges.

Do we really give developers the rights to execute stored procedures on the Test and the Production Systems. (In my office, Change Management is required on the Test and Production Systems) and granting such privileges will mean no one needs to raise an CR in the first place.

If you're a member of sysadmin, then you can grant or deny whatever privillages you know are really required. You can even edit and recompile the stored procedures too. Don't let some 3rd party tell you how to manage your database.


As a counter to that you should remember that the code whether stored procedures or otherwise should have been tested and signed off before being put LIVE. This testing may and change control may be governed by statutary requirements and so altering it without a full retest may have legal implications. As such you should not be changing the stored procs but instead requiring the developers to do so.
On the other hand it is reasonable to require the developers to produce the code such that it will work correctly on a server with much more restrictive permissions.
As a developer I would expect very liberal rights on the develpment server - definitely DBO and probably SysAdmin. I would expect TEST to be more restricted - no SYSADMIN, maybe DBO but probably only DBREADER, DBWriter and appropriate EXECUTE permissions and minimal rights on the LIVE box.
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