Skip to content

Get the most out of MSSQL !

Consultant & Trainer for all things MSSQL

  • Home
  • Company
  • Business Intelligence
  • Simply Better Business

SQL 2016 -Row level security misuse: – Visual Totals in SSAS

Posted on August 21, 2015March 20, 2021 by jayanth.kurup

Ever since I heard of Row level security I have been wanting to try it out. Not the usual stuff that I was sure MS would have already handled and tested for but the more unusual security loop holes in it one of which I have mentioned at the very bottom of this post. Those of us who have worked in Analysis Services know that we have been able to achieve row level filters (in a much more perfect way than in DB Engine) for many years now. The more important aspect of how it was achieved in SSAS was the ability to control visual totals. What this means is that in SSAS when aggregating the default member ALL was used to show grand totals this meant that the report would look something like this.

RegionSales
India$250,000
Total$500,00

This lets the India VP know that he contributes 50% of the total sales and thus has power over the others, by simply checking the box for visual totals for the user permissions in SSAS the grand totals reflect accurately as $250,000 and the VP has no clue where he stands among the others.

I was interested in seeing if this would be possible in SQL 2016 and created the below scripts.

Create the test tables and populate with data

CREATE SCHEMA rls
GO
-- creating a table to test rls
CREATE TABLE rls.rlstbl
( id int ,
name varchar(128) ,
DOB datetime,
emailid varchar(128))
GO
-- inserting test data into table

INSERT [rls].[rlstbl] ([id], [name], [DOB], [emailid]) VALUES (1, N'Jayanth', CAST(N'2012-12-12T00:00:00.000' AS DateTime), N'a@j.com')
GO
INSERT [rls].[rlstbl] ([id], [name], [DOB], [emailid]) VALUES (2, N'James', CAST(N'2012-12-13T00:00:00.000' AS DateTime), N'b@a.com')
GO
INSERT [rls].[rlstbl] ([id], [name], [DOB], [emailid]) VALUES (3, N'Jim', CAST(N'2012-12-14T00:00:00.000' AS DateTime), N'c@a.com')
GO
INSERT [rls].[rlstbl] ([id], [name], [DOB], [emailid]) VALUES (4, N'Jake', CAST(N'2012-12-15T00:00:00.000' AS DateTime), N'd@a.com')
GO
INSERT [rls].[rlstbl] ([id], [name], [DOB], [emailid]) VALUES (5, N'Andrew', CAST(N'2012-12-16T00:00:00.000' AS DateTime), N'e@b.com')
GO
INSERT [rls].[rlstbl] ([id], [name], [DOB], [emailid]) VALUES (6, N'Ajay', CAST(N'2012-12-17T00:00:00.000' AS DateTime), N'f@b.com')
GO
INSERT [rls].[rlstbl] ([id], [name], [DOB], [emailid]) VALUES (7, N'Alex', CAST(N'2012-12-18T00:00:00.000' AS DateTime), N'g@b.com')
GO
INSERT [rls].[rlstbl] ([id], [name], [DOB], [emailid]) VALUES (8, N'Susan', CAST(N'2012-12-12T00:00:00.000' AS DateTime), N'h@c.com')
GO
INSERT [rls].[rlstbl] ([id], [name], [DOB], [emailid]) VALUES (9, N'Sandra', CAST(N'2012-12-13T00:00:00.000' AS DateTime), N'i@c.com')
GO
INSERT [rls].[rlstbl] ([id], [name], [DOB], [emailid]) VALUES (10, N'Shika', CAST(N'2015-12-14T00:00:00.000' AS DateTime), N'j@c.com')

GO

Next we creat the users who will fetch data from the above table.


-- creating users based on the data
CREATE USER [a@j.com] WITHOUT LOGIN;
CREATE USER [e@b.com] WITHOUT LOGIN;
CREATE USER [h@c.com] WITHOUT LOGIN;
GO
-- granting permissions to users based on the data
GRANT SELECT ON rls.rlstbl to [a@j.com]
GRANT SELECT ON rls.rlstbl to [e@b.com]
GRANT SELECT ON rls.rlstbl to [h@c.com]
GRANT UPDATE ON rls.rlstbl to [h@c.com]
GRANT INSERT ON rls.rlstbl to [h@c.com]
GRANT DELETE ON rls.rlstbl to [h@c.com]
GRANT DELETE ON rls.rlstbl to [e@b.com]
GO

The next thing we need to do is create a table valued function ,for DBA the closest thing this comes to is the Classifier function used with Resource Governor, the table valued function is joined internally with the base table to filter rows belonging to the user. ( this aspect is hidden from the user and visible via the execution plan). In my function below I have created 4 common scenarios I come across.

  • The managerwho wants to view the date for his entire team but cannot view others data
  • The Super user who can view data for all teams but is not a DBA
  • The DBA
  • The Lowly user who can view just his data and nothing else.

CREATE FUNCTION rls.rlspredicate(@emailid AS sysname)
RETURNS TABLE
WITH SCHEMABINDING
AS
RETURN SELECT 1 AS rlspredicate_op
WHERE 1= case when USER_NAME()=@emailid then 1
when USER_NAME() ='e@b.com' and @emailid like '%@b.com%' then 1
when USER_NAME() like '%@j.com%' then 1
when user_name() ='dbo' then 1
else 0
end
-- Applying the secuity policy
CREATE SECURITY POLICY rowFilter
ADD FILTER PREDICATE rls.rlspredicate(emailid)
ON rls.rlstbl
WITH (STATE = ON);

GO

Now we test the standard Select , insert update and delete statments and they all work as expected.

EXECUTE AS USER = 'a@j.com';
SELECT *, user_name() FROM rls.rlstbl;
REVERT;

-- A low level user account who can view only his data
EXECUTE AS USER = 'h@c.com';
SELECT *, user_name() FROM rls.rlstbl;
REVERT;

-- A Team lead account who can view his entire teams data
EXECUTE AS USER = 'e@b.com';
SELECT *, user_name() FROM rls.rlstbl;
REVERT;
-- A DBA account
SELECT *, user_name() FROM rls.rlstbl;

GO

EXECUTE AS USER = 'h@c.com';
Update rls.rlstbl
set [name] ='Jim'
where id = 9

Update rls.rlstbl
set [name] ='Susan'
where id = 8

Update rls.rlstbl
set [emailid] ='e@b.com'
where id = 8

INSERT [rls].[rlstbl] ([id], [name], [DOB], [emailid]) VALUES (11, N'Samantha', CAST(N'2012-12-12T00:00:00.000' AS DateTime), N'h@c.com')
INSERT [rls].[rlstbl] ([id], [name], [DOB], [emailid]) VALUES (12, N'Saroj', CAST(N'2012-12-12T00:00:00.000' AS DateTime), N'b@b.com')
REVERT;

EXECUTE AS USER = 'e@b.com';
DELETE FROM rls.rlstbl
WHERE id = 8
REVERT

SELECT * FROM rls.rlstbl

Till here everything works as expected and now I try running the below query to view how much I or my team contribute to the total Sales of the company by simply running the query below, you will notice that running this query doesnt require any special permissions

EXECUTE AS USER = 'e@b.com';

DECLARE @int FLOAT = (SELECT ROWS FROM sys.partitions WHERE object_id = object_id('rls.rlstbl'))
select count(*)/@int from rls.rlstbl
REVERT

Screenshot below

I honestly feel that security policies for row level security should ignore system catalogs since the practical usage of this features is for application functionality. In all fairness MS has called out advanced querying as a potential loop hole but I hardly consider this advanced querying.

Please Consider Subscribing

Subscribe

CategoriesDatabasesTagsability, account, administration, advanced querying, age, AI, Analysis, Analysis service, Analysis Services, API, app, application, ASP, aspect, AVG, AWS, Azure, Bangalore, Base Table, base64, BCP, Bengaluru, BigData, bind, BLR, box, bug, Business Intelligence, CaL, call, case, CAST, Catalog, CHAR, check, Cloud, clue, code lang, common scenario, company, Consultant, Consulting, COO, Corporate, count, CREATE, Create Table, CREATE USER, CTE, Data, database, date, datetime, dba, dbo, DDT, Dec, DECLARE, development, DMV, DOB, doc, DSV, dwb, email, emailid, Enabled Business Solutions, end, etl, exe, exec, EXECUTE, execution plan, expert, feature, fPn369NW, fun, function, functionality, grand total, Grant, GRANT DELETE, GRANT SELECT, group, gun, guy, hand, hole, image, important aspect, index, India, insert, int, interest, internal, James, Jayanth, Jim, job, jsp, kid, Kurup, LAG, law, level, lib, login, mail, manager, MAX, mdf, mdx, mean, member, Migration, min, ML, ms sql server, MSBI, MSSQL, MYSQL, name, need, network, notice, NSF, object, object_id, ol style, Oracle, part, partition, pdf, perfect way, permission, plan, png, pop, post, power, power pivot, Power Query, PowerApps, PowerBI, Powershell, pre, Python, Qty, Query, rate, RDBMS, red, region, Remote, report, resource, Resource Governor, REVERT, rlspredicate, row, row level security, ROWS, run, sale, scenario, Schema, screenshot, script, sec, security, SELECT, service, set, show, side, SKU, source, sql, SQL 2000, SQL 2005, SQL 2008, sql 2008 r2, sql 2012, SQL 2014, SQL 2016, SQL 2017, SQl 2019, SSAS, SSIS, SSMS, SSRS, standard, state, sure MS, Susan, sys, T-SQL, tab, Tables, task, TCP, team, test, test data, test table, thing, tie, ton, tools, total, trainer, Transact, tsql, tuning, update, Upgrade, Uri, usage, user, user account, USER_NAME, UTF, value, VALUES, varchar, Very large database, view, Virtual, virtual machine, VISIBLE, visual studio, visual total, VM, VPN, vQe, windows, work, ws3, WtW, year

jayanth.kurup

This post was written by Jayanth Kurup. A Microsoft SQL Server Consultant and Trainer based out of Bangalore, India. Jayanth has been working on MS SQL Server for over 15 years. He is a performance tuning and Business Intelligence expert. Having worked with companies like Microsoft, DELL, Wells Fargo, Thomson Reuters and many other fortune 100 companies. Some other technologies Jayanth works on include Microsoft Azure, PowerBI, Python and AWS. When he isn’t consulting or training, Jayanth like to travel, paint and read. He is also very active in social causes and the founder of Enabled Business Solutions. Visit his company by clicking the link in the menu or email him directly.

Post navigation

PreviousPrevious post: Security: Capturing additional login information Trace vs Audit
NextNext post: Lock, Latches, Waits and Deadlocks explained weirdly (like never before)!!!

The Latest

  • Monty Hall Simulation using T-SQL April 5, 2022
  • Query to quickly profile a column February 7, 2022
  • Outlook 2019 keeps asking for password multiple times December 9, 2021
  • Part 2:- Learning T SQL for beginners – Datatypes September 28, 2021
  • Part 1:- Learning T SQL for beginners- SQL, Tables and Nulls September 27, 2021
  • Query to find execution time of Jobs July 28, 2021
  • A simple script to decapitalize Column names July 19, 2021
  • My personal side effects with Covishield June 27, 2021
  • Setting up and Configuring CUDA, CUDNN and PYTorch for Python Machine Learning. June 3, 2021
  • keras.utils.generic_utils’ has no attribute ‘populate_dict_with_module_objects May 30, 2021

Find By Category

  • Azure
  • Databases
  • Events
  • Performance Tuning
  • PowerBI
  • Uncategorized
  • Website Design

Archive

  • April 2022 (1)
  • February 2022 (1)
  • December 2021 (1)
  • September 2021 (2)
  • July 2021 (2)
  • June 2021 (2)
  • May 2021 (2)
  • April 2021 (5)
  • March 2021 (10)
  • January 2021 (2)
  • November 2020 (2)
  • October 2020 (3)
  • September 2020 (4)
  • August 2020 (6)
  • July 2020 (1)
  • June 2020 (32)
  • May 2020 (18)
  • April 2020 (2)
  • March 2020 (4)
  • February 2020 (5)
  • January 2020 (1)
  • December 2019 (1)
  • November 2019 (14)
  • October 2019 (3)
  • September 2019 (1)
  • July 2019 (3)
  • June 2019 (2)
  • May 2019 (1)
  • April 2019 (2)
  • March 2019 (1)
  • January 2019 (4)
  • December 2018 (2)
  • November 2018 (4)
  • September 2018 (6)
  • August 2018 (2)
  • July 2018 (3)
  • June 2018 (4)
  • May 2018 (1)
  • April 2018 (4)
  • March 2018 (3)
  • February 2018 (3)
  • January 2018 (1)
  • December 2017 (2)
  • November 2017 (4)
  • August 2017 (2)
  • July 2017 (5)
  • May 2017 (1)
  • March 2017 (3)
  • January 2017 (3)
  • December 2016 (2)
  • November 2016 (2)
  • October 2016 (4)
  • September 2016 (1)
  • August 2016 (1)
  • July 2016 (1)
  • June 2016 (1)
  • May 2016 (2)
  • April 2016 (1)
  • March 2016 (14)
  • February 2016 (10)
  • January 2016 (19)
  • December 2015 (3)
  • November 2015 (5)
  • October 2015 (10)
  • September 2015 (9)
  • August 2015 (16)
  • July 2015 (13)
  • June 2015 (4)
  • May 2015 (2)
  • April 2015 (2)
  • March 2015 (7)
  • February 2015 (3)
  • January 2015 (22)
  • December 2014 (1)
  • November 2014 (5)
  • October 2014 (12)
  • September 2014 (5)
  • August 2014 (7)
  • July 2014 (41)
  • June 2014 (9)
  • May 2014 (12)
  • April 2014 (32)

Members Only

  • Log in
  • Entries feed
  • Comments feed
  • WordPress.org
Proudly powered by WordPress