SQL Server Security: The db_executor Role

  • Comments posted to this topic are about the content posted at http://www.sqlservercentral.com/columnists/bkelley/sqlserversecuritythedb_executorrole.asp

    K. Brian Kelley
    @kbriankelley

  • This is a very good way to go. I would also add that you might want to do the same things with views!!!

  • Hi Brian

    Yep, deal with this one regularly and its real pain if there are large numbers of stored procs and you have inherited a system where "dbo" privs are the apparent norm!

    Cheers

    Ck

    http://www.chriskempster.com


    Chris Kempster
    www.chriskempster.com
    Author of "SQL Server Backup, Recovery & Troubleshooting"
    Author of "SQL Server 2k for the Oracle DBA"

  • We have a similar role in our development, testing, and production environments. It never occured to me to set something up to automatically grant execute permissions.

    I agree with Brian that the db_executor role would make a nice addition to the SQL Server roles.

    Nice article Brian.

    Robert W. Marda

    SQL Programmer

    bigdough.com

    The world’s leading capital markets contact database and software platform.

    Robert W. Marda
    Billing and OSS Specialist - SQL Programmer
    MCL Systems

  • I can't claim credit for the idea. I saw it in something that Richard Waymire of Microsoft wrote. However, it's an easy concept to make happen.

    K. Brian Kelley

    http://www.truthsolutions.com/

    Author: Start to Finish Guide to SQL Server Performance Monitoring

    http://www.netimpress.com/shop/product.asp?ProductID=NI-SQL1

    K. Brian Kelley
    @kbriankelley

  • I would have to say that this is indeed a good idea for development environment. We have been implementing this on our dev environment. I have to agree with Brian that the problem with this is, of course, keeping the permissions up-to-date. And I would like to share our own way of dealing with this. We have also created a SQL Server Agent for the script that grants permission on all stored procedure to a particular role but as a DBA, i didn't assign a schedule for it to run, instead, I created an alert for that when triggered, will then trigger the SQL Server Agent that runs the script. So when a developer creates or drop&re-create a stored procedure, all he has to do is to execute a raiserror to trigger the SQL Server Agent that grants execute permission on all stored procedure for that particular role.

    I hope I was able to share something worthwhile.

    Lhot

  • That works well, too. You know, that technique solves an issue I've seen posted here a lot... how to give developers the ability to create objects as dbo but without giving them the ability to carte-blanche change security settings!

    K. Brian Kelley

    http://www.truthsolutions.com/

    Author: Start to Finish Guide to SQL Server Performance Monitoring

    http://www.netimpress.com/shop/product.asp?ProductID=NI-SQL1

    K. Brian Kelley
    @kbriankelley

  • We use a dozen or so standard database roles - often added to the model database to save recreating in each new database, examples are:

    LOG_WRITER

    USER_READ

    USER_WRITE

    ADMIN_READ

    ADMIN_WRITE

    USER_EXECUTE

    ADMIN_EXECUTE

    NO_ACCESS

    AS these roles are standard and appear in all databases (dev, test & live) - All stored procedure and table scripts in SourceSafe inlude the granting of relevant permissions to all standard roles.

    So if I'm creating a sproc called GetRecentTrades I will grant execute permissions to USER_EXECUTE and possibly ADMIN_EXECUTE. I don't care which users will be given permission to use that sproc later - that can be handled in production (ultimately). This means that I can manage permissions at the initial coding stage rather than in implementation to each successive environment - avoiding the risk that permissions for some action might be missed in live.

    The NO_ACCESS role is standard and all permissions are always denied to every object (sprocs, tables, views etc.) - with CASCADE. This makes decommissioning selected user accounts easier. I'm sure many of you have experienced the problem where a user account may have more than one use - but not necessarily documented. I can add this user to NO_ACCESS in one or more databases and if something unexpectedly breaks it's relatively simple to take the user out of NO_ACCESS in the relevant database(s) - especially when compared to how you'd recover after deleting that user.

    It's always interesting to know what fellow professionals think of how one does things so please feel free to comment.

    Greg M Lucas
    "Your mind is like a parachute, it has to be open to work" - Frank Zappa

  • Very nice article. I I think it would be a god idea to create a template for stored proc, at the end of it's creation it grants permission for db_executor for itself, no ?

  • Typically, I recommend creating the permissions with the stored proc and then whatever change control mechanism you use, stored procedure and permissions are stored together to be run together. Eliminates a lot of error.

    K. Brian Kelley

    http://www.truthsolutions.com/

    Author: Start to Finish Guide to SQL Server Performance Monitoring

    http://www.netimpress.com/shop/product.asp?ProductID=NI-SQL1

    K. Brian Kelley
    @kbriankelley

  • Agreed all round. We've been using this model for some years years now and it has made a world of difference.

    It's a moot point - but how many DBA's out there are in a position where they have a say in what authentication models get used?

    I am surprised by the number of of client's DBA's who are held responsible for the integrity of the databases under their jurisdiction - whilst at the same time have absolutely no say in the security/access models used by developers.

    Have other folks out there found this to be a problem?

  • Yup, sure have. And I've been in this position as a systems administrator with responsibility over the enterprise no authority. That's just as bad.

    K. Brian Kelley

    http://www.truthsolutions.com/

    Author: Start to Finish Guide to SQL Server Performance Monitoring

    http://www.netimpress.com/shop/product.asp?ProductID=NI-SQL1

    K. Brian Kelley
    @kbriankelley

  • We should also grant to db_executor the EXECUTE permission for scalar functions.

    It is interesting to note that:

    - Inline Table-valued Functions have SELECT, INSERT, UPDATE and DELETE permissions

    - Multi-statement Table-valued Functions have only the SELECT permission

    - Scalar Functions have only the EXECUTE permission

    Here is how I would write the SELECT statement for the cursor:

    SELECT USER_NAME(uid) as Owner, [name] as StoredProcedure

    FROM sysobjects so WHERE (xtype='P' or xtype='FN')

    AND OBJECTPROPERTY([id], N'IsMSShipped')=0

    AND [id] NOT IN (SELECT [id] FROM sysprotects sp

    WHERE UID=USER_ID('db_executor') AND [action]=224)

    Razvan

  • I'd also add to the comments about production and use of change management procedures. I'd never allow a procedure that automatically granted changed permissions to users to run in production (or for that matter test). Permissions to production data should be controlled, and in my view test should replicate the live environment - with the exception of the specific change that you are testing.

     



    Niall Litchfield
    Senior DBA
    http://www.niall.litchfield.dial.pipex.com

  • Dear Brian:

    I really am a fan of yours after going thru this..

    In my case, I took it a step further by adding the Table functions and the regular functions... I thank you very much for your contribution...I am a happy DBA!

    Enclosed is the code for a stored proc which incorporates the granting of permissions to stored procs, table functions and regular functions. By creating this procedure in master database, I can call it from any user database to maintain permissions for the db_executor role.

    MELVYN

    Create proc sp_grantpermsprocsfunctions

    as

    /**  Procedure :   sp_grantpermsprocsfunctions

    **                    

    **  File      :    

    **    

    **  Author: MELVYN PATRICK LOPEZ     

    **  Date:  03/08/2006

    **

    **  Description : This Procedure is to be used to maintain db_executor role

    **                    Inspired by Brian Kelly at SQL SERVER CENTRAL

    **                   

    **                      

    **               

    **  Parameters : NONE

    **

    **  Return Values :      

    **   

    **  Data Retrieval Values: 

    ** 

    **  Errors: 

    **

    **  Tables

    **     Select : cursor

    **                    

    **       

    **     Insert :

    **       

    **     Update :

    **                     

    **     Delete : 

    **        

    **  Procedures :

    **     Calls :   sp_executesql 

    **       

    **     Called by : 

    **     

    **  Modified:

    **

    **

    */ 

    BEGIN

    DECLARE @sql nvarchar(4000),

      @Owner sysname,

      @StoredProcedure sysname,

      @Return int

    -- Cursor of all the stored procedures in the current database

    DECLARE cursStoredProcedures CURSOR FAST_FORWARD

    FOR

    SELECT USER_NAME(uid) Owner, [name] StoredProcedure

    FROM sysobjects

    WHERE xtype = 'P'

    OPEN cursStoredProcedures

    -- "Prime the pump" and get the first row

    FETCH NEXT FROM cursStoredProcedures

    INTO @Owner, @StoredProcedure

    -- Set the return code to 0

    SET @Return = 0

    -- Encapsulate the permissions assignment within a transaction

    BEGIN TRAN

    -- Cycle through the rows of the cursor

    -- And grant permissions

    WHILE ((@@FETCH_STATUS = 0) AND (@Return = 0))

      BEGIN

        -- Create the SQL Statement. Since we're giving

        -- access to all stored procedures, we have to

        -- use a two-part naming convention to get the owner.

        SET @sql = 'GRANT EXECUTE ON [' + @Owner

              + '].[' + @StoredProcedure

              + '] TO db_executor'

        -- Execute the SQL statement

        EXEC @Return = sp_executesql @sql

        -- Get the next row

        FETCH NEXT FROM cursStoredProcedures

        INTO @Owner, @StoredProcedure

      END

    -- Clean-up after the cursor

    CLOSE cursStoredProcedures

    DEALLOCATE cursStoredProcedures

    -- Check to see if the WHILE loop exited with an error.

    IF (@Return = 0)

      BEGIN

        -- Exited fine, commit the permissions

        COMMIT TRAN

      END

    ELSE

      BEGIN

        -- Exited with an error, rollback any changes

        ROLLBACK TRAN

       

        -- Report the error

        SET @sql = 'Error granting permission to ['

        + @Owner + '].[' + @StoredProcedure + ']'

        RAISERROR(@SQL, 16, 1)

      END

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

    DECLARE cursTableFunctions CURSOR FAST_FORWARD

    FOR

      SELECT USER_NAME(uid) Owner, [name] TableFunction

       FROM sysobjects

       WHERE xtype = 'TF'

    OPEN cursTableFunctions

    -- "Prime the pump" and get the first row

    FETCH NEXT FROM cursTableFunctions

    INTO @Owner, @StoredProcedure

    -- Set the return code to 0

    SET @Return = 0

    -- Encapsulate the permissions assignment within a transaction

    BEGIN TRAN

    -- Cycle through the rows of the cursor

    -- And grant permissions

    WHILE ((@@FETCH_STATUS = 0) AND (@Return = 0))

      BEGIN

        -- Create the SQL Statement. Since we're giving

        -- access to all stored procedures, we have to

        -- use a two-part naming convention to get the owner.

        SET @sql = 'GRANT SELECT ON [' + @Owner

              + '].[' + @StoredProcedure

              + '] TO db_executor'

        -- Execute the SQL statement

        EXEC @Return = sp_executesql @sql

        -- Get the next row

        FETCH NEXT FROM cursTableFunctions

        INTO @Owner, @StoredProcedure

      END

    -- Clean-up after the cursor

    CLOSE cursTableFunctions

    DEALLOCATE cursTableFunctions

    -- Check to see if the WHILE loop exited with an error.

    IF (@Return = 0)

      BEGIN

        -- Exited fine, commit the permissions

        COMMIT TRAN

      END

    ELSE

      BEGIN

        -- Exited with an error, rollback any changes

        ROLLBACK TRAN

       

        -- Report the error

        SET @sql = 'Error granting permission to ['

        + @Owner + '].[' + @StoredProcedure + ']'

        RAISERROR(@SQL, 16, 1)

      END

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

    DECLARE cursFunctions CURSOR FAST_FORWARD

    FOR

      SELECT USER_NAME(uid) Owner, [name] fFunction

       FROM sysobjects

       WHERE xtype = 'FN'

    OPEN cursFunctions

    -- "Prime the pump" and get the first row

    FETCH NEXT FROM cursFunctions

    INTO @Owner, @StoredProcedure

    -- Set the return code to 0

    SET @Return = 0

    -- Encapsulate the permissions assignment within a transaction

    BEGIN TRAN

    -- Cycle through the rows of the cursor

    -- And grant permissions

    WHILE ((@@FETCH_STATUS = 0) AND (@Return = 0))

      BEGIN

        -- Create the SQL Statement. Since we're giving

        -- access to all stored procedures, we have to

        -- use a two-part naming convention to get the owner.

        SET @sql = 'GRANT EXECUTE ON [' + @Owner

              + '].[' + @StoredProcedure

              + '] TO db_executor'

        -- Execute the SQL statement

        EXEC @Return = sp_executesql @sql

        -- Get the next row

        FETCH NEXT FROM cursFunctions

        INTO @Owner, @StoredProcedure

      END

    -- Clean-up after the cursor

    CLOSE cursFunctions

    DEALLOCATE cursFunctions

    -- Check to see if the WHILE loop exited with an error.

    IF (@Return = 0)

      BEGIN

        -- Exited fine, commit the permissions

        COMMIT TRAN

      END

    ELSE

      BEGIN

        -- Exited with an error, rollback any changes

        ROLLBACK TRAN

       

        -- Report the error

        SET @sql = 'Error granting permission to ['

        + @Owner + '].[' + @StoredProcedure + ']'

        RAISERROR(@SQL, 16, 1)

      END

    END

    GO

     

     

Viewing 15 posts - 1 through 15 (of 20 total)

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