How is my user getting update permissions through stored procedure?

  • 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.

  • 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


    --help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

  • 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

  • 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 Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • 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.

  • 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, 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
  • Thanks Gail

  • Yes, thanks for the responses.

    Martin

  • 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" 😉

  • dp.nametype_descclass_descpermission_namestate_descname

    mydbuserSQL_USERDATABASECONNECTGRANTdbo

    mydbuserSQL_USERDATABASEEXECUTEGRANTdbo

Viewing 10 posts - 1 through 9 (of 9 total)

You must be logged in to reply to this topic. Login to reply