Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 12»»

Stored Procedures Execute Permissions Expand / Collapse
Author
Message
Posted Saturday, April 13, 2013 11:35 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Friday, May 2, 2014 1:35 AM
Points: 4, 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.
Post #1442086
Posted Sunday, April 14, 2013 4:31 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Today @ 8:19 AM
Points: 40,208, Visits: 36,617
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 2008, MVP
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

Post #1442100
Posted Sunday, April 14, 2013 9:31 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Friday, May 2, 2014 1:35 AM
Points: 4, 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?
Post #1442158
Posted Monday, April 15, 2013 3:16 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Today @ 8:19 AM
Points: 40,208, Visits: 36,617
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 2008, MVP
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

Post #1442210
Posted Monday, April 15, 2013 8:34 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Today @ 8:13 AM
Points: 1,708, Visits: 4,854
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.
Post #1442332
Posted Wednesday, April 17, 2013 5:57 PM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 10:47 AM
Points: 7,126, Visits: 12,727
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
Post #1443555
Posted Thursday, April 18, 2013 8:34 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Friday, May 2, 2014 1:35 AM
Points: 4, 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.
Post #1443910
Posted Thursday, April 18, 2013 8:39 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Today @ 8:19 AM
Points: 40,208, Visits: 36,617
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 2008, MVP
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

Post #1443912
Posted Thursday, April 18, 2013 9:40 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Today @ 8:13 AM
Points: 1,708, Visits: 4,854
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.
Post #1443955
Posted Monday, April 22, 2013 5:59 AM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Tuesday, October 21, 2014 2:23 AM
Points: 217, Visits: 869
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.
Post #1444938
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse