Database Journal
MS SQL Oracle DB2 Access MySQL PostgreSQL Sybase PHP SQL Etc SQL Scripts & Samples Links Database Forum

» Database Journal Home
» Database Articles
» Database Tutorials
MS SQL
Oracle
DB2
MS Access
MySQL
» RESOURCES
Database Tools
SQL Scripts & Samples
Links
» Database Forum
» Sitemap
Free Newsletters:
DatabaseDaily  
News Via RSS Feed


follow us on Twitter
Database Journal |DBA Support |SQLCourse |SQLCourse2
 

Featured Database Articles

MS SQL

Posted Aug 13, 2003

Managing Users Permissions on SQL Server - Page 2

By Alexander Chigrik

Enhancing Security Using Views

Views can be used to enhance security because permissions to access a view can be granted, denied, or revoked, regardless of the set of permissions to access the underlying table(s).

Views can also be used to limit the data that is available to a user. For example, one peace of data can be accessible to users for modifications while another piece of data can be accessible to users for query, and the rest of the data is invisible and inaccessible.

Views can be used to restrict access to the following subsets of data:

  • A subset of the rows of a base table
  • A subset of the columns of a base table
  • A subset of combination of rows and columns of a base table
  • A subset of another view or some combination of views and tables
  • A statistical summary of data in a base table


For example, consider a scenario where you need to manage permissions to the employee table for the Accounting, Sales, and the Tech Windows 2000 groups, and each group has their corresponding SQL Server roles namely: the Accounting, Sales, and Tech respectively. Let's say the employee table was created using the following CREATE TABLE statement:

CREATE TABLE employee(
   EmployeeId INT NOT NULL PRIMARY KEY,
   LName VARCHAR(30) NOT NULL,
   FName VARCHAR(30) NOT NULL,
   Address VARCHAR(100) NOT NULL,
   HireDate DATETIME NOT NULL,
   Salary MONEY NOT NULL
)

Suppose you need to assign the Accounting role access to query the entire employee table, the Sales role to access only the LName, FName, and HireDate columns of the employee table, and the Tech role should not have any access either to the view or to the employee table itself. This can be achieved using the following script:

-- grant select permission on the employee table to the Accounting role
GRANT SELECT ON employee TO Accounting
GO

-- deny select permission on the employee table from the Tech and Sales role
-- to ensure these roles do not have select permission on the employee table
DENY SELECT ON employee TO Sales, Tech
GO

-- create the view that limits access the employee table to the Sales role
CREATE VIEW employee_view
AS
SELECT LName, FName, HireDate 
FROM employee
GO

-- grant select on the employee_view to the Sales group
GRANT SELECT ON employee_view TO Sales
GO

Using Stored Procedures to Enhance Security

Stored procedures can be used to enhance security in much the same way as views. The permissions to execute a stored procedure can be granted, denied, or revoked instead of granting permissions on the underlying data objects. Stored procedures can be used to conceal the underlying data objects too. For example, you can give a user only the permission to execute a stored procedure and the user will not know anything about underlying data objects. By using stored procedures, you can also limit the data that is available to a user. You can give the users only permission to execute a stored procedure to work with the restricted set of the columns and rows instead of querying the entire table.

For example, the Salary and the Address columns in the employee table contain confidential employee information and should be available only to the members of the Accounting database role, but the rest of the columns contain information that should be available to all database users.

This script shows how the above security task can be achieved:

-- grant select permission on the employee table to the Accounting
-- role
GRANT SELECT ON employee TO Accounting
GO

-- create the stored procedure that hides 
-- Salary and the Address columns in the employee table 
CREATE PROCEDURE employee_proc
AS
SELECT LName, FName, HireDate 
FROM employee
GO

-- grant select permission on the employee_proc to the public role
GRANT EXECUTE ON employee_proc TO public
GO

Because each database user has the public role permission, you can grant the desirable permission to the public role if you need to grant this permission to all database users. If the business logic of your application allows some users to update values in several columns in the table without having permission to update anything else on the table, you can also use a stored procedure.

For example, any members of the Accounting database role are allowed to update the Salary column in the employee table without having permission to update other columns. The employee table was created using the following CREATE TABLE statement:

The following script shows how the above security task can be achieved:

-- deny UPDATE, DELETE and INSERT permissions 
-- on the employee table to the Accounting role
-- to ensure this role does not have these permissions
DENY UPDATE, DELETE, INSERT ON employee TO Accounting
GO

-- create the stored procedure that modify the Salary
-- column on the employee table for the employee passed
CREATE PROCEDURE employee_proc_upd 
  @EmployeeID int,
  @Salary money
AS
UPDATE employee 
SET Salary = @Salary
WHERE EmployeeID = @EmployeeID
GO

-- grant execute on the employee_proc_upd to the Accounting role
GRANT EXECUTE ON employee_proc_upd TO Accounting
GO

Permissions Intersection

Under the permissions intersection we understand the results permission, which a user will have when different permissions were granted or revoked to this user or (and) for the roles to which this user belong. A permissions conflict can arise, if the user is a member of several roles with different permissions to access an object.

As we described above, permissions can be granted, revoked, or denied.

The GRANT statement removes the denied or revoked permission at the level granted, so the denied permission at another level still applies. For example, if you need to allow the user Alex to select the employee table and the select permissions were denied to both user Alex and Accounting role to which Alex belongs, you can run the following statement:

GRANT SELECT ON employee TO Alex, Accounting


A denied permission overrides all other permissions and always takes precedence. For example, a user belongs to two roles: Accounting and Technology. The Accounting role gives the user select, insert, delete, and update permissions. The Technology role provides select but denies permissions for insert, delete, and update. The result is the user only can select regardless that the user belongs to the Accounting role. You can deny permissions to the public role, if you need to prevent anyone from accessing an object. The results of using the DENY statement against a database object looks like the results of granting the 'No Access' permission to the Windows NT user account.

The REVOKE statement is used to remove a previously granted or denied permission at the level revoked, so the same permission granted or denied at another level still applies. For example, if you need to prevent the user Alex from selecting the employee table and the select permissions were granted to both user Alex and Accounting role to which Alex belongs, you can run one of the following statements:

REVOKE SELECT ON employee FROM Alex, Accounting
DENY SELECT ON employee TO Alex
DENY SELECT ON employee TO Accounting

» See All Articles by Columnist Alexander Chigrik



MS SQL Archives

Comment and Contribute

 


(Maximum characters: 1200). You have characters left.

 

 




Latest Forum Threads
MS SQL Forum
Topic By Replies Updated
SQL 2005: SSIS: Error using SQL Server credentials poverty 3 August 17th, 07:43 AM
Need help changing table contents nkawtg 1 August 17th, 03:02 AM
SQL Server Memory confifuration bhosalenarayan 2 August 14th, 05:33 AM
SQL Server Primary Key and a Unique Key katty.jonh 2 July 25th, 10:36 AM


















Thanks for your registration, follow us on our social networks to keep up-to-date