SharePoint Pals
 | Sign In
Steps to configure row level security in SQL Server 2016
by Krishna KV 9 Jul 2016
Author
Team Leader, Aspire Systems
Visits   
Today  :   9     Total  :    3875

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
blog comments powered by Disqus

SharePoint Pals

Pals
SharePoint Pals, a community portal for SharePoint developers, Administrators and End Users. Let's join hands and share the point together.
Read this on mobile

Training

Angular Js Training In Chennai
Advanced Angular Js training with real world developer scenarios
Angular Js, Web Api and Ionic for .Net Developers
All in one client side application development for .Net developers
Angular Js For SharePoint Developers
Get ready for the future. Its no more just C#

Get Connected

SharePoint Resources

SharePoint 2013 and 2010 Web Parts
Free Web Parts with Source Code for SharePoint Community




SharePoint 2013 Books and Tutorials
Collection of free SharePoint 2013 books and tutorials (eBooks, pdfs)

Supported By

Contribute your article and be eligible for a one month Free Subscription for Plural Sight. The Author of the most popular New Article (published in the previous month) will be awarded with a Free One month Plural Sight Subscription. Article can be sent to articles@sharepointpals.com in a word document.

Related Resources

Recent Tweets

Twitter January 15, 00:25
How To Enable Target Value And Actual Value In #D3 Gauge Chart https://t.co/VxSi4QnNrC

Twitter January 15, 00:24
How To Open #SharePoint List Hyperlink Column In Modal #Popup Window https://t.co/EQ7HkoZDkX

Twitter January 15, 00:24
Quick Introduction To #Asp.NetCore And It’s Features https://t.co/zAXObHCFpH

Twitter January 15, 00:22
How To Configure #PerformancePoint Services To Use Secure Store In #SharePoint 2013 https://t.co/LEwnUoI7EY

Twitter January 15, 00:21
How To Block Or Disable #Office365 Services https://t.co/Yvp2VPFIRP

Follow us @SharePointPals
Note: For Customization and Configuration, CheckOutRecent Tweets Documentation