Category Archives: Database Design

Restricting Data Access with Row Level Security – Part 2

Remain calm…Row Level Security is not that scary, if you read this blog series.

In Part 1 of this series, we introduced Row Level Security (RLS) and the table-valued function (TVF) that will be used to filter data, based on a specific user. The sample queries filtered data by cross-applying the table with the function. Manually filtering data is great, but RLS allows us to formalize the filter and be used for every query that uses the table.

Defining the Security Policy

In SQL Server, Security Policies are used to bind the TVF to one or more tables. Below is an example of a security policy in our Endless Timekeeping database.

CREATE SECURITY POLICY [App].[FilterUsersPolicy] 
ADD FILTER PREDICATE [App].[udf_UsersFilter]([UserID]) ON [App].[Users]
WITH (STATE = ON, SCHEMABINDING = ON)

Let’s create a template of the statement and break it down.

CREATE SECURITY POLICY <schema>.<name>
ADD <FILTER OR BLOCK> PREDICATE <Table-Valued Function>(<Field from table>) ON <schema>.<table>
WITH (STATE = <ON OR OFF>, SCHEMABINDING = <ON OR OFF>)

As with any SQL Server object, it needs to be named, and added to a schema, even if it’s in dbo. Next, define what type of policy is being implemented, either a filtering policy or a blocking policy. Filtering policies are used to filter SELECT statements, while blocking policies are used for INSERT/UPDATE/DELETE statements. In our case, we’re currently working with filtering SELECT statements. We’ll use the function created in Part 1 of this series, App.udf_UsersFilter, and “bind” it to the intended table, App.Users.

Finally, we need to decide whether or not to use schema binding. It is recommended to use SCHEMABINDING = ON, but it is not required. Should you choose not to use SCHEMABINDING, remember every user (or a group and/or role) will need to be given access to the predicate function, in addition to the table(s). If SCHEMABINDING is enabled, then users who have access to the table will have permission to the predicate function. For my database, I have no reasons to disable it, so I won’t and will leave it on. Once the security policy has been created in the database, our test queries from the previous blog can be modified and re-tested.

The image above has the relevant list of employees in our company, with each employee’s department name and the ID of their direct supervisor. As a refresher, or if you haven’t read Part 1 of this series, below is the predicate function we’ve defined for the App.Users table.

CREATE FUNCTION [App].[udf_UsersFilter]
(
    @UserID INT
)
RETURNS TABLE
WITH SCHEMABINDING
AS
RETURN
(
    -- Allow access to the user's own record
    SELECT 1 FilterResult
    FROM App.Users u
    WHERE u.UserID = @UserID
          AND USER_NAME() = u.Username
    UNION
    -- Allow access to the user's direct reports' records 
    SELECT 1 FilterResult
    FROM App.Users u
        LEFT JOIN App.Users m
            ON u.ManagerID = m.UserID
    WHERE u.UserID = @UserID
          AND USER_NAME() = m.Username
    UNION
    -- Allow access to all users for members of the HumanResources role
    SELECT 1
    FROM App.Users
    WHERE UserID = @UserID
          AND IS_ROLEMEMBER('HumanResources') = 1
);

Our first test is with our office manager, Peggy. Her user is able to see just her record, as she is not a manager, nor is she a member of the HumanResources database role (cases 2 and 3 of the predicate function defined in Part 1).

To query the App.Users table, we can just call the table and not have to worry about the predicate function or having a WHERE clause that filters records appropriately.

EXECUTE AS USER = 'PeggyM'

SELECT u.*
FROM App.Users u

The second test case is with my database user, ErinD. In this example, my record and my direct reports’ records are returned (cases 1 and 2 in the predicate function).

EXECUTE AS USER = 'ErinD'

SELECT u.*
FROM App.Users u

From here on out, anyone who queries the table will receive a filtered list of data from the App.Users table. IMPORTANTLY, this includes database administrators. DBAs are not able to view all of the data in the table, unless they disable the security policy (not recommended) or they belong to the HumanResources database role. The “god” role of sysadmin does not take priority over RLS.

The examples shown so far have been developed after quite a bit of trial and error. In the next blog in this series, we’ll discuss the DOs and DON’Ts when it comes to Row Level Security. We will then investigate improvements to our design to better handle real-world, enterprise implementations of RLS.

Restricting Data Access with Row Level Security – Part 1

When starting a new company, and you’ve added at least one other staff member, one of the most important applications you can have is a time tracking system. Time tracking is even more important for a consulting company, so customers are billed appropriately and we get paid. Depending on the number of features of this system, there is likely to be personal information, such as hourly or monthly salary, perhaps a Social Security Number (in the U.S.), or other information that needs to be kept private for each employee.

Of course, the time tracking application will filter this data, as we build it, but we will have a lot of smart developers, who will know where the SQL server is and will likely have some level of access to it. As a result, we need to lock down the data in the database itself, not just in how the application queries and displays the data. As of SQL Server 2016, Microsoft has implemented Row Level Security, allowing DBAs to secure data, by limiting who can see specific records in a protected table.

Getting the hang of RLS took a little bit of time and experimenting. One of my sources of inspiration came from the great Steve Jones with one of his stairway articles on Row Level Security.

Components for Row Level Security

To implement Row Level Security, you will need the following objects in your database.

  • Table needing to be secured
  • Predicate function – needs to determine if the user has access to a record
  • Security Policy – ties the table(s) to a predicate function

Predicate Function

The first step is to identify a table for which to enable RLS. You may have a table identified already, as you’re thinking about RLS. In this blog, we’ll be working with the Users table, shown in the diagram above. Other blogs will work with the TimeEntries table for RLS, as that table will need to be locked down.

The next step is to create a predicate function. This is a table-valued function that needs to return 1 value to show the user has access to the requested record in the table. Through the use of the security policy, which we’ll cover in a later blog, this function will be applied automatically to every query that calls the table…regardless of user or level of access to the database.

To filter the Users table the way we want, at least initially, the table-valued function below will fit the bill. The function has 3 union’d queries, each returning the value “1” for records a particular user has access to.

CREATE FUNCTION [App].[udf_UsersFilter]
(
    @UserID INT
)
RETURNS TABLE
WITH SCHEMABINDING
AS
RETURN
(
    -- Allow access to the user's own record
    SELECT 1 FilterResult
    FROM App.Users u
    WHERE u.UserID = @UserID
          AND USER_NAME() = u.Username
    UNION
    -- Allow access to the user's direct reports' records 
    SELECT 1 FilterResult
    FROM App.Users u
        LEFT JOIN App.Users m
            ON u.ManagerID = m.UserID
    WHERE u.UserID = @UserID
          AND USER_NAME() = m.Username
    UNION
    -- Allow access to all users for members of the HumanResources role
    SELECT 1
    FROM App.Users
    WHERE UserID = @UserID
          AND IS_ROLEMEMBER('HumanResources') = 1
);

We’ll test each section of the function, running them as different users. Currently, we have three users we’ll test. In the first case, Peggy is our “office Mom,” or office manager, who keeps everyone in line but she doesn’t have any direct reports. The query returns just her record User record.

EXECUTE AS USER = 'PeggyM'

SELECT u.* FROM App.Users u
CROSS APPLY App.udf_UsersFilter(u.UserID) p

REVERT

I’m the President of the company, and Peggy and Jill report directly to me. Running the query with my login, three records are returned, my own record, as well as Peggy and Jill’s records. Sections 1 and 2 of the function are being tested.

EXECUTE AS USER = 'ErinD'

SELECT u.* FROM App.Users u
CROSS APPLY App.udf_UsersFilter(u.UserID) p

REVERT

The final test is for our Human Resources team, and Sarah Jones in particular. As a member of HR, she has the ability to see all employees, because she’s a member of the HumanResources database role.

EXECUTE AS USER = 'SarahJ'

SELECT u.*
FROM App.Users u
CROSS APPLY App.udf_UsersFilter(u.UserID) p

REVERT

To this point, we’ve written our filtering predicate function for the App.Users table. This is great, but we shouldn’t have to worry about this function and applying it each and every query that hits the Users table. Besides myself, as the developer of the function, any other developers don’t need to be aware of the function, but we need to filter the table each and every time.

Tying the function to the table will be in the next blog. Stay tuned…