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

How is my user getting update permissions through stored procedure? Expand / Collapse
Author
Message
Posted Wednesday, February 19, 2014 8:56 AM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Friday, July 18, 2014 3:59 PM
Points: 1,314, Visits: 547
I have a user that has db_datareader role on a database and explicit grant Connect and Execute permissions on the same database, there are no other permissions set.

My user is executing a stored procedure that is defined as Execute as Caller.

The procedure does an update, and with the permissions as above should not be able to run the procedure, but it does run and does update the table.

According to the documentation this should not be possible.
Post #1543082
Posted Wednesday, February 19, 2014 9:22 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 7:11 PM
Points: 12,876, Visits: 31,789
ownership chaining, and it's the default behavior.

if you grant EXECUTE on a procedure to a user with no other permissions, as long as the stored procedure only touches objects in the same schema(dbo, probably) and in the same database,
the procedure will perform and execute it's code on it's underlying objects udner the context of the owner...insert,update, delete and more, even to objects the end user doesn't even know exist.

this is specifically so end users don't need permissions to the actual tables themselves.


Lowell

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #1543097
Posted Wednesday, February 19, 2014 9:50 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, July 15, 2014 1:50 AM
Points: 3, Visits: 26
Thanks for your answer Lowell - that is the conclusion we are coming to.

But are you able to point us at a manual entry explaining what you say.

We were looking at the Permissions section in this entry http://technet.microsoft.com/en-us/library/ms188332(v=sql.105).aspx - the third line below fits the scenario and the update should not be allowed:


If the module accesses other database objects, execution succeeds when you have EXECUTE permission on the module and one of the following is true:
•The module is marked EXECUTE AS USER or SELF, and the module owner has the corresponding permissions on the referenced object. For more information about impersonation within a module, see EXECUTE AS Clause (Transact-SQL).
The module is marked EXECUTE AS CALLER, and you have the corresponding permissions on the object.
•The module is marked EXECUTE AS user_name, and user_name has the corresponding permissions on the object
Post #1543110
Posted Wednesday, February 19, 2014 10:15 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 2:50 PM
Points: 13,062, Visits: 11,891
steve.barfield (2/19/2014)
Thanks for your answer Lowell - that is the conclusion we are coming to.

But are you able to point us at a manual entry explaining what you say.

We were looking at the Permissions section in this entry http://technet.microsoft.com/en-us/library/ms188332(v=sql.105).aspx - the third line below fits the scenario and the update should not be allowed:


If the module accesses other database objects, execution succeeds when you have EXECUTE permission on the module and one of the following is true:
•The module is marked EXECUTE AS USER or SELF, and the module owner has the corresponding permissions on the referenced object. For more information about impersonation within a module, see EXECUTE AS Clause (Transact-SQL).
The module is marked EXECUTE AS CALLER, and you have the corresponding permissions on the object.
•The module is marked EXECUTE AS user_name, and user_name has the corresponding permissions on the object


Notice that only 1 of those needs to be true. Most likely the first one is true.


_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Post #1543120
Posted Wednesday, February 19, 2014 11:13 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, July 15, 2014 1:50 AM
Points: 3, Visits: 26
Thanks Sean - we had made it clear that the procedure was defined as EXECUTE AS CALLER.

But after a bit of thought it is clear now - Lowell was right.

Dbo owns the procedure and owns the table that the procedure updates - so anyone who can EXECUTE the procedure will get it to update the table regardless of whether they have update rights on the table.

The EXECUTE AS CALLER definition would only come in to play if the procedure updated a table that dbo did not own.

Thanks for your advice on this question.
Post #1543144
Posted Thursday, February 20, 2014 12:40 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: Yesterday @ 4:54 PM
Points: 42,434, Visits: 35,488
The relevant page in the docs - http://technet.microsoft.com/en-us/library/ms188676%28v=sql.105%29.aspx


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 #1543348
Posted Thursday, February 20, 2014 4:30 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, July 15, 2014 1:50 AM
Points: 3, Visits: 26
Thanks Gail
Post #1543405
Posted Thursday, February 20, 2014 7:41 AM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Friday, July 18, 2014 3:59 PM
Points: 1,314, Visits: 547
Yes, thanks for the responses.
Martin
Post #1543499
Posted Sunday, February 23, 2014 10:52 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 8:08 AM
Points: 6,162, Visits: 13,305
Martin_Burton (2/19/2014)
I have a user that has db_datareader role on a database and explicit grant Connect and Execute permissions on the same database, there are no other permissions set.

My user is executing a stored procedure that is defined as Execute as Caller.

The procedure does an update, and with the permissions as above should not be able to run the procedure, but it does run and does update the table.

According to the documentation this should not be possible.

Can you return results of this please

use yourdb
select dp.name
, dp.type_desc
, dp2.class_desc
, dp2.permission_name
, dp2.state_desc
, dp3.name
from sys.database_principals dp
inner join sys.database_permissions dp2 on dp.principal_id = dp2.grantee_principal_id
inner join sys.database_principals dp3 on dp2.grantor_principal_id = dp3.principal_id
where dp.name = 'yourdbuser'



-----------------------------------------------------------------------------------------------------------

"Ya can't make an omelette without breaking just a few eggs"
Post #1544297
Posted Monday, February 24, 2014 9:04 AM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Friday, July 18, 2014 3:59 PM
Points: 1,314, Visits: 547
dp.name type_desc class_desc permission_name state_desc name
mydbuser SQL_USER DATABASE CONNECT GRANT dbo
mydbuser SQL_USER DATABASE EXECUTE GRANT dbo
Post #1544579
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse