Skip to main content

Execute Permissions

Written by David Postlethwaite

Security of the SQL database is becoming more and more important these days yet I’m finding that vendors often overlook setting minimum required privileges on a database. Many database I’ve been given to install just assign db_owner to the user accounts that really only need read and write. This means that those accounts can do whatever they want to the database, even dropping it.

 
But if you try and fix this by limiting that account to datareader and datawriter you often find that the application no longer works because the account can’t execute any stored procedures or functions. The vendor has relied on the fact that db_owner can do anything so no explicit execute permissions have been given.

So how do we fix this?

 
In a previous article Gethyn showed how to grant implicit execute permissions to the whole database to a new role called db_executer.

CREATE ROLE db_executor
GRANT EXECUTE TO db_executor



Then you just need to give the users datareader, datawriter and db_executer and hopefully everything will carry on working.
 
But from a support view , if another DBA looked at the properties of a stored procedure in SSMS he wouldn’t immediately see this as the explicit permissions screen would not show that the user had execute permissions for that particular stored procedure.


 
To assign explicit execute permissions to every stored procedure and function something slightly more complex is required. The code below will find all the stored procedures and functions in a database and create the appropriate T-SQL statement to grant the db_executer role execute permissions (or select permissions for a table value function)


For safety this will print the T-SQL, you will need to uncomment the exec line if you want it to run. Or you could put the output to text and copy and paste it into a query window and run it like that

CREATE ROLE db_executor

-- Declare Variables
DECLARE @cmd1 varchar(8000)
DECLARE @SchemaName varchar(128)
DECLARE @ProcName varchar(128)
DECLARE @ProcType varchar(128)
DECLARE @FuncType varchar(128)

-- Create Cursor
DECLARE temp_cursor CURSOR FOR
select routine_schema,routine_name,routine_type,data_type from information_schema.routines
where routine_type in('function','procedure')
order by routine_type desc, data_type

-- loop through cursor
OPEN temp_cursor
FETCH NEXT FROM temp_cursor
INTO @SchemaName ,@ProcName, @ProcType, @FuncType

WHILE @@FETCH_STATUS = 0
BEGIN
-- Build the cmd string
IF @ProcType='Procedure' OR (@ProcType='function' AND @FuncType<>'table')
BEGIN
SELECT @cmd1 = 'GRANT EXEC ON ' + '[' + @SchemaName + ']' + '.' + '[' + @ProcName + ']' + ' TO db_executor'
END

IF @ProcType='function' AND @FuncType='table'
BEGIN
SELECT @cmd1 = 'GRANT SELECT ON ' + '[' + @SchemaName + ']' + '.' + '[' + @ProcName + ']' + ' TO db_executor'
END

-- Execute the string
print @cmd1
-- EXEC(@cmd1)

FETCH NEXT FROM temp_cursor
INTO @SchemaName ,@ProcName, @ProcType, @FuncType
END

CLOSE temp_cursor
DEALLOCATE temp_cursor



I hope you find this useful

Comments

Popular posts from this blog

SQL Server 2012 and Virtual Service Accounts

This post is written by David Postlethwaite
If you are using SQL Server 2012 you will probably have noticed that the default account for the SQL services has changed from that used in previous versions. With SQL 2005 and 2008 the default account for SQL service and SQL Agent service was “NT Authority\System”. This is one the built in accounts on a Windows machine, managed by the machine and selectable from a dedicated dropdown list

The Network Service account was introduced in Windows 2003 as an alternative to using the LocalSystem account, which has full local system privileges on the local machine, a major security concern.
The Network Service has limited local privileges easing these security concerns but when many services on a machine use the Network Service account it becomes harder to track which service is actually accessing resources and performing actions, because all the services are using the one Network Service account.
Also, this account, by default, has sysadmin per…

Always Encrypted

By David Postlethwaite

Always Encrypted is new features in SQL Server 2016 and it is also available in Azure SQL Database. Here you can encrypt columns in a table with a master key and a certificate so that they will appear as encrypted strings to those who don’t have the required certificate installed on their pc.
Once the certificate is installed on the computer then the unencrypted data can then be seen as normal.

The data passes from database to your application as the encrypted value, only the application with the correct certificate can unencrypt the data so it is secure across the wire. This will go some way to resolving the concern of people worried about putting their sensitive data on a shared server in the cloud such as Microsoft Azure and accessing the data across the Internet.

At the time of writing Always Encrypted is only supported with ADO.NET 4.6, JDBC 6.0 and ODBC 13.1 but expect other driver to become available.

The calling application (including SSMS) must also hav…

How to Setup Kerberos Correctly

David was in Copenhagen this weekend delivering his Kerberos talk Taming the Beast: Kerberos for the SQL DBA to SQL Saturday Denmark. I have had a quick chat with him via email since he got back and he said he had a great time. The event was very well attended with 280+ attendees and his talk was well attended.

I think David is planning submitting a few sessions to SQL Saturday events in Europe in the next few months so look out for him there and we'll keep you posted as to his whereabouts when schedules get finalised later in the year.

David has pre-recorded his Kerberos talk. You can watch on you tube and I have also embedded it in this post if you want to see what his kerberos talk  covers...



If we can help you with a SQL Sever problem visit our SQL Server Consulting page or contact us