6.7 KiB
Use VIEWs with JOIN into Permission-Assignments for Row-Level-Security
Status:
- proposed by Michael Hönnig
- accepted by (Participants)
- rejected by (Participants)
- superseded by (superseding ADR)
Context and Problem Statement
We need to decide how to apply the access rules defined in our RBAC system to the visibility of table rows for the accessing user.
The core problem here is, that in our RBAC system, determining the permissions of the accessing user has to consider a hierarchy of roles.
Technical Background
The session variable hsadminng.currentUser
contains the accessing (domain-level) user, which is unrelated to the PostgreSQL user).
Given is a stored function isPermissionGrantedToSubject
which detects if the accessing user has a given permission (e.g. 'view').
Given is also a stored function queryAllPermissionsOfSubjectId
which returns the flattened view to all permissions assigned to the given accessing user.
In the following code snippets customer
is just an example domain table.
Considered Options
- Perform Visibility-Checks programmatically in the Backend
- Add Visibility-Checks in the Backend
- POLICY with ENABLE ROW LEVEL SECURITY
- VIEW-RULE with ON SELECT DO INSTEAD
- VIEW with JOIN into Flattened Permissions
Perform Visibility-Checks programmatically in the Backend
In this solution, the database ignores row level visibility and returns all rows which match a given query. Afterwards, the result is filtered programmatically with Java-code in the backend.
Advantages
Very flexible access, programmatic, rules could be implemented.
The role-hierarchy and permissions for currently logged-in users user could be cached in the backend.
The access logic can be tested in pure Java unit tests.
At least regarding this aspect, an in-memory database could be used for integration testing; though the recursive Role-evaluation uses PostgreSQL features anyway.
Disadvantages
It's inefficient when initial query is not very restrictive, e.g. as on overview pages in a frontend, which often show all accessible objects, large parts or even whole database tables need to be transferred from the database to the backend.
It's error-prone and security leaks can happen too easily, because after every query the access rights for all participating joins have to be considered.
Add Visibility-Checks in the Backend
In this solution again, the database ignores row level visibility and returns all rows which match a given query. And the backend adds filter conditions to each query sent to the database.
Advantages
At least regarding this aspect, an in-memory database could be used for integration testing.
Disadvantages
It's error-prone and security leaks can happen too easily, because for every query the access rights for all participating joins have to be considered.
POLICY with ENABLE ROW LEVEL SECURITY
For restricted DB-users, which are used by the backend, access to rows is filtered using a policy:
SET SESSION AUTHORIZATION DEFAULT;
CREATE ROLE restricted;
GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO restricted;
ALTER TABLE customer ENABLE ROW LEVEL SECURITY;
CREATE POLICY customer_policy ON customer
FOR SELECT
TO restricted
USING (
isPermissionGrantedToSubject(findPermissionId('customer', id, 'view'), currentUserUuid())
);
SET SESSION AUTHORIZATION restricted;
SET hsadminng.currentUser TO 'alex@example.com';
SELECT * from customer; -- will only return visible rows
Advantages
Using POLICY together with ENABLE ROW LEVEL SECURITY is the PostgreSQL native mechanism to control access to data on the role level. Therefore, it looked like an obvious and elegant solution.
Every access at from the backend is under access control at the database level.
Disadvantages
Unfortunately security mechanisms in PostgreSQL prevent the query optimizer to work well beyond ownership barriers (session user vs. table owner) and a SELECT from a table with 1 million objects needed over 30 seconds with our hierarchical RBAC policy.
We are bound to PostgreSQL, including integration tests and testing the RBAC system itself.
VIEW-RULE with ON SELECT DO INSTEAD
SET SESSION SESSION AUTHORIZATION DEFAULT;
CREATE VIEW cust_view AS
SELECT * FROM customer;
CREATE OR REPLACE RULE "_RETURN" AS
ON SELECT TO cust_view
DO INSTEAD
SELECT * FROM customer WHERE isPermissionGrantedToSubject(findPermissionId('customer', id, 'view'), currentUserUuid());
SET SESSION AUTHORIZATION restricted;
SET hsadminng.currentUser TO 'alex@example.com';
SELECT * from customer; -- will only return visible rows
Advantages
Every access at from the backend is under access control at the database level.
Also using ON UPDATE etc., original tables could be completely hidden from the backend, and thus improved security.
Disadvantages
Unfortunately security mechanisms in PostgreSQL prevent the query optimizer to work well beyond ownership barriers (session user vs. table owner) and a SELECT from a table with 1 million objects needed over 30 seconds with our hierarchical RBAC policy.
We are bound to PostgreSQL, including integration tests and testing the RBAC system itself.
An extra view needed for every table.
VIEW with JOIN into flattened permissions
We do not access the tables directly from the backend, but via views which join the flattened permissions
SET SESSION SESSION AUTHORIZATION DEFAULT;
CREATE OR REPLACE VIEW cust_view AS
SELECT c.id, c.reference, c.prefix
FROM customer AS c
JOIN queryAllPermissionsOfSubjectId(currentUserUuid()) AS p
ON p.tableName='customer' AND p.rowId=c.id AND p.op='view';
GRANT ALL PRIVILEGES ON cust_view TO restricted;
SET SESSION SESSION AUTHORIZATION restricted;
SET hsadminng.currentUser TO 'alex@example.com';
SELECT * from cust_view; -- will only return visible rows
Alternatively the JOIN could also be applied in a "ON SELECT DO INSTEAD"-RULE, if there is any advantage for later features.
Advantages
Every access at from the backend is under access control at the database level.
No special PostgreSQL features needed; though the recursive Role-evaluation uses PostgreSQL features anyway.
Very fast, on my laptop a SELECT * FROM a table with 1 million rows just took about 50ms.
Also using ON UPDATE etc., original tables could be completely hidden from the backend, and thus improved security.
Disadvantages
An extra view needed for every table.
Decision Outcome
We chose the option "VIEW with JOIN into flattened permissions" because it supports the best combination of performance and security with almost no disadvantge.