cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
vedran Regular Visitor
Regular Visitor

Re: Row Level Security in Power BI Report Server

Great! Thanks a lot for the quick answer

Chai Visitor
Visitor

Re: Row Level Security in Power BI Report Server

@davidm5 Can you explain step by step process. How can we use SYSTEM_USER in SQL Server?

davidm5 Frequent Visitor
Frequent Visitor

Re: Row Level Security in Power BI Report Server

All right, here's my best attempt to walk through it.  For this example I’ll be using the AdventureWorksDW2012 database.

 

For my hypothetical case, I’ve got regional sales directors that should only be able to see information for employees that are in their assigned sales territories.  I’m going to implement that by putting a security policy on the DimEmployee table.  In summary the steps are:

  1. Create and populate a new table that defines which sales territories a particular user (as defined by their Windows login ID) is allowed to access.
  2. Create a new function in SQL Server that checks the relationship between user and allowed sales territories.
  3. Create a new security policy on the DimEmployee table using the function created in step 2.

Once those steps are done I can create a report in Power BI that accesses the DimEmployee table and take advantage of the implemented RLS.

 

In more detail:

 

  1. Create a new table that defines which sales territories a user may access.  I called my table SalesTerritoryRLS.  It’s a simple table with two columns that looks like this:

NetID

SalesTerritoryKey

Davidm5

1

Davidm5

4

SomeOtherUser

2

 

The NetID column is simply the Windows user ID of the user, and SalesTerritoryKey correlates to the column SalesTerritoryKey in the DimEmployee table.  So as currently populated this table says that I (davidm5) am allowed to see data for sales territories 1 and 4; the user ‘SomeOtherUser’ is allowed to see data for sales territory 2.

 

  1. Create a new function in SQL Server. The SQL to create the function looks like this: 

SET ANSI_NULLS ON

GO

 

SET QUOTED_IDENTIFIER ON

GO

 

CREATE FUNCTION [dbo].[fn_SalesTerritory_SecurityPredicate] (@salesTerritory AS int)

RETURNS TABLE

WITH SCHEMABINDING

AS

RETURN

       SELECT 1 AS fn_SecurityPredicateResult

       FROM dbo.SalesTerritoryRLS rls

       WHERE rls.SalesTerritoryKey = @salesTerritory

              AND rls.NetID = SYSTEM_USER

GO

 

We’ll apply this function as a filter in the next step.  Basically this function checks to see if the sales territory on a row it’s evaluating is one of the sales territories the currently logged in user is allowed to access.  That’s where SYSTEM_USER comes in – see the final line of the WHERE clause.  SYSTEM_USER is the ID of the currently logged in user.

 

  1. Create a security policy using the function. The SQL for this is:

CREATE SECURITY POLICY [dbo].[dimEmployeeFilter]

ADD FILTER PREDICATE [dbo].[fn_SalesTerritory_SecurityPredicate]([SalesTerritoryKey]) ON [dbo].[DimEmployee]

WITH (STATE = ON, SCHEMABINDING = ON)

GO

 

This ties the function created above to the DimEmployee table.  When you do any SQL operation on the table, it passes in the SalesTerritoryKey for each row and the function is used to determine if it’s a row the user is allowed to access, based on the values in the RLS table created in step 1.

 

Now you’re free to access DimEmployee in your Power BI report and RLS will be enforced.  Note that for this to work you MUST use ‘Windows Authentication’/’As the user viewing the report’ on the Data Source Settings for the report.

 

Notice that creating the function and applying it as a security policy are two different steps.  That means you could apply that same function to multiple tables to implement our RLS on sales territory across multiple tables if you’d like.

 

Also be aware that this means RLS is applied at the data layer; for any tool the user might use to access the DimEmployee table, RLS will be applied.  Even if I log into SSMS directly to query the DimEmployee table, I’ll only be able to see rows where the sales territory is 1 or 4.  And the way I wrote this particular function means that by default users get NO access to DimEmployee data; until a row is entered for them in the SalesTerritoryRLS table, they won’t be able to see any DimEmployee data.

 

Rook Frequent Visitor
Frequent Visitor

Re: Row Level Security in Power BI Report Server

davidm5, this is the method we've got running on our database layer, RLS is enabled for the currently connected user. The only issue we're having is passing the logged in user's credentials to the database via the report in the Report Server (on-prem). Do you have a similar set up or any insight this double-hop authentication? 

Highlighted
davidm5 Frequent Visitor
Frequent Visitor

Re: Row Level Security in Power BI Report Server

I'm about out of my depth here, but I'll try to help.

 

When you set up the report on Report Server, when you go to Manage > Data Sources and look at the Credentials section, you MUST use 'Windows Authentication' as the Authentication Type, and you MUST use the 'As the user viewing the report' option.

 

Then in SQL Server, for whatever database you're using that same user ID must have permissions on the database.  I think just db_datareader is all you need but I'm not certain about that.

 

The only trick we do is to use an active directory group.  This is where I'm sketchy, but if I understand it correctly we actually give the AD group the SQL permissions, then just add the Windows user ID to that AD group.  It isn't necessary to do it this way, it just makes our user management a little easier.  We already have mechanisms in place to handle adding and removing users from the AD group as employment and roles change - by using the AD group we don't have to seperately manage SQL permissions per user ID.

 

I hope that helps.  If not, if you can provide details I can try and provide more info.

Rook Frequent Visitor
Frequent Visitor

Re: Row Level Security in Power BI Report Server

Hmm. Thanks Davidm5, but we've already got that setup. We have a group saved into the DB Server and have datareader permissions set for the required DB.

 

The  following link in a previous thread describes our setup: DirectQuery-Login-failed-for-user-NT-AUTHORITY-ANONYMOUS-LOGON.

 

I'll clarify the problem by saying that the DirectQuery and RLS stuff works - but only when viewing the report via Chrome. Using IE throws either a Kerberos constrained delegation error, or 'connection string not properly formed' error. So even though we're looking at the same report, different browsers behave differently.

 

Internet options have been set on IE and the site has been added as 'Intranet' level security. 

 

Smiley Frustrated

 

 

davidm5 Frequent Visitor
Frequent Visitor

Re: Row Level Security in Power BI Report Server

I'm sorry I don't have an answer for you, but I can tell you that it's working in IE for us so I can confirm it's possible.  I don't know what magic the networking folks might have done behind the scene to pull that off though.

Rook Frequent Visitor
Frequent Visitor

Re: Row Level Security in Power BI Report Server

No problems davidm5, we managed to figure it out, thanks for your contribution.

 

For those of you still struggling with Kerberos authentication between an SQL Server (2016) and On-Prem report server, here is a few things to check when following the Kerberos configuration article posted on the MSDN.

 

  • Ensure your user has access to the datasource with datareader permissions, either via a dedicated logon or as part of a group logon.
  • Ensure that you set up constrained delegation for the  (domain) user accounts that run SQL Server and Report Server
  • Ensure that you have enabled constrained delegation on the server accounts themselves (i.e. the Computer's AD Entry must allow for Kerberos Authentication)

 

 

That last, bolded part is what had caused us headache. From our perspective, it seems that the MSDN article missed a few steps..

 

 

andy_scott42 Regular Visitor
Regular Visitor

Re: Row Level Security in Power BI Report Server

I'm trying to do something similar with the SQL server security table but ran into problems. 

 

I have my table of users and can filter the SQL queries fine using the current user. However, when I run a scheduled refresh of the data in Report server it uses the specified credentials and so returns no data. 

 

I tried creating a measure using CurrentUser = USERNAME() and then filtering the model by this but it won't let me use this measure in a table filter.

 

I want to refresh the data with the admin credentials and return all rows, then filter by the current user.

 

Any suggestions?

davidm5 Frequent Visitor
Frequent Visitor

Re: Row Level Security in Power BI Report Server

If I understand what you're trying to do, you're NOT using a security policy in SQL Server for RLS.  I say that because that technique doesn't work if you're doing scheduled refreshes, it only works for direct query.  If I've misunderstood, my apologies.

 

So with the assumption I understand what you're trying to do, here's an approach:

 - You'll need a table in your report that links user ID's to whatever the filter field is.  Let's call it SalesTerritoryRLS.  It only needs to have two columns, one with the user ID and the second with the filter value.  It's the table I gave in step 1 of my example earlier in this thread.

- Create a measure that looks like this:  filterRLS = CALCULATE(COUNTROWS(SalesTerritoryRLS), SalesTerritoryRLS[NetID] = USERNAME())

- Now add a visual level filter to the visual that's displaying the data you want to filter where filterRLS is 1

 

I've done this as proof of concept, but not tried it in anything that's been deployed to a large set of users, so it's possible there are problems with this approach I've not run across.  In my proof of concept it worked fine.

 

Helpful resources

Announcements
Ask Amir Anything

Exclusive LIVE Community Event No. 2 – Ask Amir Anything

Next in our Triple A series: Ask Amir Netz questions about the latest updates, features and future.

Ask Amanda Anything Q&A

Ask Amanda Anything Q&A

Learn the answers to some of the questions asked during the Amanda Triple A event.

October 2019 Community Highlights

October 2019 Community Highlights

October was a busy month in the community. Read the recap article to learn about some of the events and content.

New Solution Badges

New Solution Badges

Two waves of brand new solution badges are coming! Read the article for more information on our new community badges.

Users Online
Currently online: 162 members 1,701 guests
Please welcome our newest community members: