Steps to configure row level security in SQL Server 2016

Krishna KV
 
Team Leader, Aspire Systems
July 9, 2016
 
Rate this article
 
Views
9891

The row level security (RLS) provides security based on the user name or login id of the current user logged in. While executing the select statement the rows are filtered based on the executing context of the query. Previous we have applied the filtered in a views or through a stored procedure, whereas the filtered will not be applied at the table level.

The table will have a security policy filter which will be executed, whereas the admin can view all the rows and others can view the data based on the security policy.

 CREATE TABLE Orders (Id INT IDENTITY(1,1) PRIMARY KEY,
 Name VARCHAR(100),OrderQuanity INT , Price  DECIMAL(10,2),UserName VARCHAR(50))
 GO
 
 INSERT INTO dbo.Orders VALUES ('Order1',10,100,'User1'),
 							('Order2',6,2.35,'User1'),
 							('Order3',5,34.23,'User2'),
 							('Order4',7,199,'User2'),
 							('Order5',12,199,'User3')
 GO

For a row level security we need to create a function & Security policy

Function for filtering the rows

This function uses the @username parameter and the value as current user using the function USER_NAME which will filter the rows with the current username. We need to associate the function to the table using a security policy.

 CREATE FUNCTION fn_orderSecurity (@userName sysname)
 RETURNS TABLE
 WITH SCHEMABINDING
 AS
 RETURN SELECT 1 AS 'orderSecurity' WHERE @userName=USER_NAME()
 
 GO

Creating a security policy

 CREATE SECURITY POLICY order_policy 
 ADD FILTER PREDICATE dbo.fn_orderSecurity(UserName) 
 ON dbo.orders 
 WITH (STATE=ON)

In the security policy above the FILTER PREDICATE is referencing the function dbo.fn_orderSecurity.  By use of the security policy the SQL Server will make sure that every time that a database user runs a SQL command that referred the orders table has the filter predicate ‘orderSecurity’ function will also be executed, thus enforcing the RLS.

 GRANT SELECT ON dbo.Orders TO PUBLIC
 
 CREATE USER user1 WITHOUT LOGIN
 CREATE USER user2 WITHOUT LOGIN
 CREATE USER user3 WITHOUT LOGIN
 
 EXEC ('Select * from orders') AS USER='User1'
 
 EXEC ('Select * from orders') AS USER='User2'
 
 EXEC ('Select * from orders') AS USER='User3'

image

image

 Alter Security Policy order_policy with (State = off)
 
 EXEC ('Select * from orders') AS USER='User3'

image

image

 SELECT * FROM sys.security_policies
 GO
 SELECT * FROM sys.security_predicates
 GO

image

 Drop Security Policy IF EXISTS fn_security
 Drop FUNCTION IF EXISTS dbo.fn_securitypredicateOrder
Category : SQL

Author Info

Krishna KV
 
Team Leader, Aspire Systems
 
Rate this article
 
Krishna K.V has been working in IT Industry for over 7+ years. He holds a Master Degree in Information Technology. He is more interested to learn and share new technologies, ...read more
 

Leave a comment