Dynamic Parent Child Security using DAX

I was recently posed a challenge to implement the following requirements in a Tabular model:

  1. Secure a Parent Child dimension at a Parent level, allowing all children to be visible
  2. Allow multiple Parents to be securable to a given user
  3. Keep it as easy to administer as possible

The first 2 requirements are technical and internal to the tabular model, but the last implied inherently that use of Roles and AD Groups was out as this is not a very user friendly approach.

Note that in this exercise I will be using the DimEmployee Dimension from the AdventureWorks 2012 DW sample database.

Row Level  Security in Tabular Models

Tabular Models apply security is applied at the row level by the application of row filters that restrict what a given Role can see. You can make the effect of a Roles dynamic through the use of  lookup tables and the USERNAME() function. There is a detailed white paper on securing Tabular Models on MSDN: Securing the Tabular BI Semantic Model

In a non-parent child situation this is simple to manage as it is easy to establish a relationship between viewable members (i.e. rows) and users via a bridging table – the paper mentioned above has a clear example of this.

How Parent Child Dimensions complicate things

Parent Child Dimensions add complications because there isn’t a straightforward relationship to manage. You can secure the parent by filtering on the parent’s unique key – as below – but any child row, while aware of the relationship to the  immediate parent via the ParentEmployeeKey cannot be filtered on the same column.

DimEmployee in AdventureWorks
DimEmployee in AdventureWorks

A consequence of this is that if you want to secure using row filters, you would need a table that secures each parent and child explicitly for each user. This is obviously not easy to administer and if the hierarchy changes you need to rebuild your security all over again.

How can I make Security Dynamic?

DAX, of course! This is a variation on the scenario described in the white paper – except in this case complicated because the table to be secured contains no data that can be used to apply security directly.

How do I apply this to a Parent-Child Dimension?

Fortunately there are ways to make rows aware of the hierarchy that applies to them. Of particular relevance in our case are the PATH and PATHCONTAINS function.

The PATH function returns a text delimited list of hierarchy members from the current member to the topmost parent. The PATHCONTAINS function scans that list for a specific member and returns a boolean TRUE/FALSE result as to whether that specific member is there. So if we have the following functions in our model:

PATH:=PATH([EmployeeKey],[ParentEmployeeKey])

PATHCONTAINS:=PATHCONTAINS(PATH([EmployeeKey],[ParentEmployeeKey]),189)

We get a set of results like this:

Parent Child Dimension with PATH and PATHCONTAINS DAX functions
Parent Child Dimension with PATH and PATHCONTAINS DAX functions

So the PATH for Employee Key 12 is “112 | 23 | 189 | 12″ – so key 12 is the leaf, and the three preceding members in the hierarchy. The PATHCONTAINS test for member 189 returns TRUE as it is present in the PATH.

So, now we have a means of evaluating in a single column what that rows place in the hierarchy is, and more importantly what its parents are.

The next challenge is to map this to the user data. Now, as I mentioned, there isn’t a meaningful relationship that can be established between the data and the security table, which I’ll show below:

PCSecurity

This means any relationship needs to be generated on the fly. Also note it’s not a single higher parent per user – a user may need to be able to view different paths in the hierarchy. An example case of this may be a manager with a responsibility for managing employees performance across multiple units but without a direct reporting line in the hierarchy.

GENERATE a relationship dynamically

The data items can be linked using the GENERATE function in conjunction with some FILTERs to determine what applies. GENERATE creates a cartesian product of two tables. So by using GENERATE between the Dimension and the Security table, we get a view of all possible user / dimension level combinations:

GENERATE(UserSecurity,DimEmployee)

Now this is only a starting point because we need to return a single value within our equation otherwise DAX will throw an error. Also, we don’t need everything from UserSecurity, just the items that apply to the current user. So first, lets FILTER our UserSecurity table:

GENERATE(FILTER(UserSecurity,UserSecurity[User]=”U4″),DimEmployee)

Note I’ve hardcoded the User here to “U4″ but in a real life context you would use the USERNAME function to get that name. Now we’ve cut down on one side of the cartesian product, but now we need to cut down the other side to get the members we are allowed to see. So here we filter using PATHCONTAINS to pick up the items that are the permitted members or children of those members:

GENERATE(FILTER(UserSecurity,UserSecurity[User]=”U4″),FILTER(‘DimEmployee’,PATHCONTAINS(PATH([EmployeeKey],[ParentEmployeeKey]),UserSecurity[Highest Parent]))

So now in the GENERATED table we have all the members of the Dimension that the current user is permitted to see.It’s worth taking a quick diversion from DAX to show how this works in practice:

PATHCONTAINS Example
PATHCONTAINS Example

Because the PATH contains the keys for all members in the hierarchy from the current member to the topmost parent, any PATH that contains the highest allowable parent will pass the PATHCONTAINS test. So if looking for member 189, rows 1&2 fail because though they are part of the overall path they are above the highest permissible member. Rows 3&4 pass because they feature the highest permissible member in the path to the topmost parent. Row 5 fails because the highest permissible parent doesn’t feature in the PATH at all.

Note that because the result at this point is still a Table as opposed to a single value, it handles users with multiple permissions correctly. The next part is to make sure that in the specific row of the Dimension we are evaluating if that row is in the permitted list, which we can do by putting an outer FILTER on the GENERATE.

FILTER(GENERATE(FILTER(UserSecurity,UserSecurity[User]=”U4″),FILTER(‘DimEmployee’,PATHCONTAINS(PATH([EmployeeKey],[ParentEmployeeKey]),UserSecurity[Highest Parent]))),DimEmployee[EmployeeKey]=EARLIER(DimEmployee[EmployeeKey]))

We use the EARLIER function to get the current value of the EmployeeKey from the outer evaluation pass and give us the context specific to this row. Our final step is to convert this into a single value, which I do using a COUNTROWS function:

COUNTROWS(FILTER(GENERATE(FILTER(UserSecurity,UserSecurity[User]=”U4″),FILTER(‘DimEmployee’,PATHCONTAINS(PATH([EmployeeKey],[ParentEmployeeKey]),UserSecurity[Highest Parent]))),DimEmployee[EmployeeKey]=EARLIER(DimEmployee[EmployeeKey])))

Because of the way the data works in this example, COUNTROWS will return either 1 if Authorised or 0 if unauthorised.

The final step is then to use this Authorised calculation in the Measures to ensure we can only see permitted values for that user, which is no more complex than:

AuthorisedSum:=CALCULATE(SUM(Data[Value]),‘DimEmployee'[Authorised]=1)

… and it’s done. Totals created by this measure will be sensitive to what the user is entitled to see and be fully aware of the Parent / Child relationship even though we only explicitly secure a parent.

Seeing this in action, we see that user U4 is authorised to see the two nodes from keys 290 (Alberts) & 294 (Abbas) and downwards:

Security Demo Pivot
Security Demo Pivot

As I mentioned previously this doesn’t secure the Hierarchy members from being visible, so the path up the tree is still visible – but there will be no values coming through that may be tied to those members.

Quick wrap

So this post has been pretty dense. If you want to get your hands on the result I have provided a sample PowerPivot workbook which has the completed example.

As a reminder, we set out to:

  1. Secure a Parent Child dimension at a Parent level, allowing all children to be visible
  2. Allow multiple Parents to be securable to a given user
  3. Keep it as easy to administer as possible

We did this by using the PATH function to make each row aware of where it was in the Parent / Child Hierarchy. Then using the GENERATE function and some FILTERs to dynamically mimic a relationship we worked out what security could apply. Finally we used the PATHCONTAINS function to work out what security applied.

So we hit point 1 on functionality, point 2 just through the nature of the solution – and by using a simple table rather than Roles / AD type solutions hit point 3.

Finally, a big hat tip to a post from Alberto Ferrari which helped me make sense of Parent Child in Tabular in the first place.

Read More