Dynamic RLS implementation in PPAS 9.3

In the course of my work at EnterpriseDB, migrating Oracle databases to EnterpriseDB’s Postgres Plus Advanced Server is a common task. However, now and then we encounter unique situations. While working on a migration project recently, we encountered a new use case for RLS (Row level Security).

The customer had a centralized database where it stored a huge number of transactions. These transactions are performed by different business units located in different parts of the world. There are certain types of transactions that should not be visible even if they are being queried by the same company. That is where RLS comes in. With RSL, specific transactions, or kinds of transactions, that can remain visible are mapped back to an attribute in the table.

The customer needed the application to authenticate users and set the context for which records in the database become visible for a specific session.
In its deployment of Oracle, the customer had used the functions/procedure in the Oracle package DBMS_SESSION. In the application, the customer used DBMS_SESSION.SET_CONTEXT to set the context. And for the Row Level Security, the customer was using the DBMS_SESSION.SYS_CONTEXT to implement security around the transactions.

Postgres Plus Advanced Server has a DBMS_SESSION package that is compatible with Oracle. However, it does not currently offer users the capability of setting the user defined context and implementing RLS based on those context. Given others may experience similar situations , as our customer, I wanted to provide the procedures and functions that users could deploy.

SET_CONTEXT procedure

The definition of this procedure is given below:

CREATE OR REPLACE PROCEDURE set_context(namespace TEXT,
                                        attribute TEXT,
                                        val       TEXT)
AS
BEGIN
    EXECUTE IMMEDIATE format('SET %s.%s TO %s',namespace, attribute,val);
END;

Using this procedure, users can set their own context at session level.

The following is a function to help view the context in session, which is set using the above procedure.

CREATE OR REPLACE FUNCTION USYS_CONTEXT(namespace TEXT,
                                        parameter TEXT,
                                        len       BIGINT DEFAULT 8)
RETURN TEXT
AS
  DECLARE
    return_val TEXT;
  BEGIN
    EXECUTE IMMEDIATE format('SHOW %s.%s',namespace,parameter) INTO return_val;
    RETURN substr(return_val,1,len);
    EXCEPTION WHEN others THEN
     RETURN NULL;
END;

The following is an example of how we can implement row level security based on the above procedure and functions:
1. Create a table which will have attribute context_check to map the context set by procedure:

CREATE TABLE test_rls(id numeric, col text, context_check text);
INSERT INTO test_rls SELECT id, 'First_check','aaa' FROM generate_series(1,10) foo(id);
INSERT INTO test_rls SELECT id, 'First_check','bbb' FROM generate_series(1,10) foo(id);
INSERT INTO test_rls SELECT id, 'First_check','ddd' FROM generate_series(1,10) foo(id);

2. Now create a function to check the application context. Below is one function:

CREATE OR REPLACE FUNCTION verify_user_context (
    p_schema       TEXT,
    p_object       TEXT
)
RETURN VARCHAR2
IS
DECLARE
   predicate TEXT;
BEGIN
    predicate := format('context_check = public.usys_context(''%s''::text,''%s''::text, 8)','CONTEXT','APP_PREDICATE');
    RETURN predicate;
END;

3. Now Apply Security Policy using Policy Functions shown below:

DECLARE
v_object_schema VARCHAR2(30) := 'public';
v_object_name VARCHAR2(30) := 'test_rls';
v_policy_name VARCHAR2(30) := 'secure_data';
v_function_schema VARCHAR2(30) := 'public';
v_policy_function VARCHAR2(30) := 'verify_user_context';
v_statement_types VARCHAR2(30) := 'INSERT,UPDATE,DELETE,SELECT';
v_update_check BOOLEAN := TRUE;
v_enable BOOLEAN := TRUE;
BEGIN
DBMS_RLS.ADD_POLICY(
v_object_schema,
v_object_name,
v_policy_name,
v_function_schema,
v_policy_function,
v_statement_types,
v_update_check,
v_enable
);
END;

Now we are set to test this implementation.

Connect to one session and try the following:
1. Set the context using procedure SET_CONTEXT as given below:

EXEC  SET_CONTEXT('CONTEXT','APP_PREDICATE','ddd');

EDB-SPL Procedure successfully completed

2. Verify in the same session to determine if we have set the Context properly:

 SELECT USYS_CONTEXT('CONTEXT','APP_PREDICATE',2000);
 usys_context
--------------
 ddd
(1 row)

3. Since in session, we have Context set as ddd, there in this session, we should be able to see rows respective to set contexts:

beta=# SELECT * FROM test_rls ;
 id |     col     | context_check
----+-------------+---------------
  1 | First_check | ddd
  2 | First_check | ddd
  3 | First_check | ddd
  4 | First_check | ddd
  5 | First_check | ddd
  6 | First_check | ddd
  7 | First_check | ddd
  8 | First_check | ddd
  9 | First_check | ddd
 10 | First_check | ddd
(10 rows)

As you can see, the DBMS_RLS package in Postgres Plus Advanced Service can help in implementing Row Level Security based on Application Context.

Virtual Private Database (VPD) in PPAS 9.1

Great News is Postgres Plus Advanced 9.1 is now available for users. So, I thought to write something about Virtual Private Database features, which is part of 9.1

Virtual Private Database (VPD) is a feature which enables Administrator to create security around actual data (i.e row/columns) so that multiple users can access data which is relevant to them. Steps which is require to create Virtual Private database is given below:
1. Create an Application Context
2. Create security policies functions
3. Apply security policies to tables

Lets see how user can implement it in Advanced Server.
1. Setup an environment as given below:

 CREATE user merry identified by edb;
 CREATE user john identified by edb;
 CREATE TABLE public.john_merry(userid varchar2(200),val numeric);
 grant select,update,delete,insert on john_merry to john;
 grant select,update,delete,insert on john_merry to merry;

2. Now create a Policy Function as given below:

 CREATE OR REPLACE FUNCTION verify_user (
 p_schema VARCHAR2,
 p_object VARCHAR2
 )
 RETURN VARCHAR2
 IS
 BEGIN
 RETURN 'userid = SYS_CONTEXT(''USERENV'', ''SESSION_USER'')';
 END;

3. Apply Security Policy using Policy Functions as given below:

 DECLARE
 v_object_schema VARCHAR2(30) := 'public';
 v_object_name VARCHAR2(30) := 'john_merry';
 v_policy_name VARCHAR2(30) := 'secure_data';
 v_function_schema VARCHAR2(30) := 'enterprisedb';
 v_policy_function VARCHAR2(30) := 'verify_user';
 v_statement_types VARCHAR2(30) := 'INSERT,UPDATE,DELETE,SELECT';
 v_update_check BOOLEAN := TRUE;
 v_enable BOOLEAN := TRUE;
 BEGIN
 DBMS_RLS.ADD_POLICY(
 v_object_schema,
 v_object_name,
 v_policy_name,
 v_function_schema,
 v_policy_function,
 v_statement_types,
 v_update_check,
 v_enable
 );
 END;

Now, lets see how it works.
First insert some records for John and Merry as given below:
1. Connect as John user and do some insert as john, as given below:

 edb=> insert into john_merry values('john',1);
 INSERT 0 1
 edb=> insert into john_merry values('john',2);
 INSERT 0 1
 edb=> insert into john_merry values('john',3);
 INSERT 0 1

2. Now connect as merry and insert some records as merry:

 edb=> insert into john_merry values('merry',1);
 INSERT 0 1
 edb=> insert into john_merry values('merry',2);
 INSERT 0 1
 edb=> insert into john_merry values('merry',3);
 INSERT 0 1

Ok. Now we have some data for both users. lets see how VPD works:
1. Connect as John User and try to insert some record for merry:

 edb=> insert into john_merry values('merry',4);
 ERROR: policy with check option violation
 DETAIL: Policy predicate was evaluated to FALSE with the updated values

hmm this is expected, VPD security policy won’t allow me to do this activity.

2. Now try to update Merry data as John User:

 edb=> update john_merry set val=4 where val=3 and userid='merry';
 UPDATE 0

No rows updated. This is expected since as per security policy merry’s data is not visible to john. However, john can update his record as given below:

 edb=> update john_merry set val=4 where val=3 and userid='john';
 UPDATE 1

3. Now, lets execute SELECT query on table to view data:

 edb=> select current_user;
 current_user
 --------------
 john
 (1 row)

edb=> select * from john_merry ;
 userid | val
 --------+-----
 john | 1
 john | 2
 john | 4
 (3 rows)

As you can see, john can see his records not merry’s. Similary user can try for Merry. Below is a snapshot of SELECT query executed by merry:
using dumb terminal settings.

 edb=> select current_user;
 current_user
 --------------
 merry
 (1 row)

edb=> select * from john_merry ;
 userid | val
 --------+-----
 merry | 1
 merry | 2
 merry | 3
 (3 rows)

Interesting!!