Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
Hello,
I've got a test .pbix model built and am trying to implement row level security but am running into issues in passing multiple filters via DAX in Manage Roles. My data model looks like this:
I'm able to successfully filter the first with the following code:
Also in text form:
[Profile] IN
SELECTCOLUMNS(
FILTER('UserProfileAbbrP&L',
'UserProfileAbbrP&L'[User] = USERPRINCIPALNAME()
),
"Profile", [Profile]
)
But I'm striking out with the best method to filter the AbbrP&L table:
Also in text form:
[Abbr P&L] IN
SELECTCOLUMNS(
FILTER('ProfileAbbrP&L',
'ProfileAbbrP&L'[Abbr P&L Account])
) IN
SELECTCOLUMNS(
FILTER('UserProfileAbbrP&L',
'UserProfileAbbrP&L'[User] = USERPRINCIPALNAME()
),
"Abbr P&L", [Abbr P&L]
)
What am I missing? I think I need to keep the structure as is (with the calculated Profile Bridge table) because there will be multiple instances of Profile in the UserProfile & ProfileAbbrP&L tables, but I am open to suggestions. I'd also like to avoid passing applying filters in both directions if possible.
Thanks in advance,
Tom
Solved! Go to Solution.
You don't actually need your security table joined into your model. You just use a measure to read the USERPRINCIPALNAME() and build the list of 'AbbrP&L'[Abbr P&L] accounts that user can see. One change you will need is to make the join between UserProfileAbbrP&L and Profile Bridge bi-directional.
Then the filter on the on the AbbrP&L table looks like this.
'AbbrP&L'[Abbr P&L] IN
CALCULATETABLE(
VALUES('ProfileAbbrP&L'[Abbr P&L Account]),'UserProfileAbbrP&L'[User]=USERPRINCIPALNAME())
I have attached my updated copy of your file for you to look at.
Your ProfileAbbrP&L already contains the accounts and the rollups that a profile can see. You just need to move the rollups to the AbbrP&L table so it looks like this:
You can remove the Rollup tables from the profile side and set the UserProfileAbbrP&L > AbbrProfileBridge back to bi directional. Then your filtering measure looks like this.
VAR _UPN = USERPRINCIPALNAME()
RETURN
'AbbrP&L'[Abbr P&L] IN
CALCULATETABLE(
VALUES('ProfileAbbrP&L'[Abbr P&L Account]),'UserProfileAbbrP&L'[User]=_UPN)
||
'AbbrP&L'[Rollup] IN
CALCULATETABLE(
VALUES('ProfileAbbrP&L'[Abbr P&L Account]),'UserProfileAbbrP&L'[User]=_UPN)
The model ends up looking like this.
And the RLS will show all the accounts or rollups assigned to the profile in the [ProfileAbbrP&L] table:
You don't actually need your security table joined into your model. You just use a measure to read the USERPRINCIPALNAME() and build the list of 'AbbrP&L'[Abbr P&L] accounts that user can see. One change you will need is to make the join between UserProfileAbbrP&L and Profile Bridge bi-directional.
Then the filter on the on the AbbrP&L table looks like this.
'AbbrP&L'[Abbr P&L] IN
CALCULATETABLE(
VALUES('ProfileAbbrP&L'[Abbr P&L Account]),'UserProfileAbbrP&L'[User]=USERPRINCIPALNAME())
I have attached my updated copy of your file for you to look at.
Thanks for the reply and the education, @jdbuchanan71! One element of the filter doesn't appear to be working correctly, however. The "Retail Stores" profile should filter to Retail Stores & Net Sales per the ProfileAbbrP&L table, do I need to alter the approach somehow?
There is no 'Net Sales' entry in the 'AbbrP&L' table so that is why it is not showing up.
This unfortunately adds another layer of complexity; I had left off my AbbrP&L rollup table for simplicity, but I'll need to filter that table as well. I can't apply bi-directional filtering off of the user table twice, which leads me with one of two options:
I would certainly like to figure out option 2, is this at all possible?
Updated .pbix, and data model screenshot below:
Your ProfileAbbrP&L already contains the accounts and the rollups that a profile can see. You just need to move the rollups to the AbbrP&L table so it looks like this:
You can remove the Rollup tables from the profile side and set the UserProfileAbbrP&L > AbbrProfileBridge back to bi directional. Then your filtering measure looks like this.
VAR _UPN = USERPRINCIPALNAME()
RETURN
'AbbrP&L'[Abbr P&L] IN
CALCULATETABLE(
VALUES('ProfileAbbrP&L'[Abbr P&L Account]),'UserProfileAbbrP&L'[User]=_UPN)
||
'AbbrP&L'[Rollup] IN
CALCULATETABLE(
VALUES('ProfileAbbrP&L'[Abbr P&L Account]),'UserProfileAbbrP&L'[User]=_UPN)
The model ends up looking like this.
And the RLS will show all the accounts or rollups assigned to the profile in the [ProfileAbbrP&L] table:
This works great, thanks @jdbuchanan71 ! I modified slightly to filter the Accounts table (as I'll also have to filter accounts). Can't wait to build it into my actual model.
Check out the September 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
112 | |
104 | |
94 | |
38 | |
30 |