Wednesday, December 10, 2014

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.

Monday, December 1, 2014

Compiling PLV8 with Postgres Plus Advanced Server

PLV8 is a programming language that lets users write stored procedures and triggers in JavaScript and store them in their Postgres database. This allows application programmers to write a lot of their server-side programming in the same language they use to build their web client applications.  Fewer languages to learn usually means fewer mistakes and faster time to completion.  The extensive language support is one of many reasons why Postgres’ use across the world is increasing lately.  The recent addition of document data support with JSON and JSONB data types in PostgreSQL, and in Postgres Plus Advanced Server from EnterpriseDB, is the main reason for the increasing interest in the PL/V8 language extension.

Below are the steps you need to compile PLV8 with Postgres Plus Advanced Server 9.3/9.4.

To get started, here are the prerequisites:
1. A supported version of PostgreSQL or Postgres Plus Advanced Server, such as versions 9.1 and higher.
2. V8 version 3.14.5
3. g++ version 4.5.1

If you want to know more about V8, you can visit the following wiki page:
http://en.wikipedia.org/wiki/V8_(JavaScript_engine)

It’s important to note that when compiling PLV8 with Postgres Plus Advanced Server 9.3 or the upcoming 9.4, you will get the following two types of error messages:

The first error:
[root@localhost plv8js]# make

sed -e 's/^#undef PLV8_VERSION/#define PLV8_VERSION "1.5.0-dev1"/' plv8_config.h.in > plv8_config.h

g++ -Wall -O2 -DV8_USE_UNSAFE_HANDLES  -I. -I./ -I/usr/ppas-9.4/include/server -I/usr/ppas-9.4/include/internal -I/usr/include/et -D_GNU_SOURCE -I/usr/include/libxml2  -I/usr/include -fPIC -c -o plv8.o plv8.cc

plv8.cc: In function ‘void _PG_init()’:

plv8.cc:226: error: invalid conversion from ‘void (*)(XactEvent, void*)’ to ‘void (*)(XactEvent, void*, bool)’

plv8.cc:226: error:   initializing argument 1 of ‘void RegisterXactCallback(void (*)(XactEvent, void*, bool), void*)’

make: *** [plv8.o] Error 1


The above error message is a result of a different signature of typedef void (*XactCallback) in the Advanced Server transaction system.

To fix the above issue, the user can replace the following in plv8.cc:
static void plv8_xact_cb(XactEvent event, void *arg);

With
static void plv8_xact_cb(XactEvent event, void *arg, bool spl_context);


The second error:
After making the above changes, you may get the following error after trying to compile the source code using the “make” command:
[root@localhost plv8js]# make

g++ -Wall -O2 -DV8_USE_UNSAFE_HANDLES  -I. -I./ -I/usr/ppas-9.4/include/server -I/usr/ppas-9.4/include/internal -I/usr/include/et -D_GNU_SOURCE -I/usr/include/libxml2  -I/usr/include -fPIC -c -o plv8.o plv8.cc

plv8.cc:137: warning: ‘void plv8_xact_cb(XactEvent, void*, bool)’ used but never defined

plv8.cc:232: warning: ‘void plv8_xact_cb(XactEvent, void*)’ defined but not used

g++ -Wall -O2 -DV8_USE_UNSAFE_HANDLES  -I. -I./ -I/usr/ppas-9.4/include/server -I/usr/ppas-9.4/include/internal -I/usr/include/et -D_GNU_SOURCE -I/usr/include/libxml2  -I/usr/include -fPIC -c -o plv8_type.o plv8_type.cc

g++ -Wall -O2 -DV8_USE_UNSAFE_HANDLES  -I. -I./ -I/usr/ppas-9.4/include/server -I/usr/ppas-9.4/include/internal -I/usr/include/et -D_GNU_SOURCE -I/usr/include/libxml2  -I/usr/include -fPIC -c -o plv8_func.o plv8_func.cc

In file included from plv8_param.h:11,

                 from plv8_func.cc:9:

/usr/ppas-9.4/include/server/nodes/params.h:77: error: expected ‘,’ or ‘...’ before ‘typeid’

make: *** [plv8_func.o] Error 1


The above is mainly due to the use of typeid in params.h; typeid is the reserved keyword of C++ compiler.

To fix this issue, make the following changes in plv8.h
extern "C" {

#include "postgres.h"



#include "access/htup.h"

#include "fmgr.h"

#include "mb/pg_wchar.h"

#include "utils/tuplestore.h"

#include "windowapi.h"

}


with
#define typeid __typeid

extern "C" {

#include "postgres.h"



#include "access/htup.h"

#include "fmgr.h"

#include "mb/pg_wchar.h"

#include "utils/tuplestore.h"

#include "windowapi.h"

}

#undef typeid


In plv8_param.h, change the following:
extern "C" {

#include "postgres.h"



/*

 * Variable SPI parameter is since 9.0.  Avoid include files in prior versions,

 * as they contain C++ keywords.

 */

#include "nodes/params.h"

#if PG_VERSION_NUM >= 90000

#include "parser/parse_node.h"

#endif // PG_VERSION_NUM >= 90000



} // extern "C"


With
#define typeid __typeid

extern "C" {

#include "postgres.h"



/*

 * Variable SPI parameter is since 9.0.  Avoid including files in prior versions,

 * as they contain C++ keywords.

 */

#include "nodes/params.h"

#if PG_VERSION_NUM >= 90000

#include "parser/parse_node.h"

#endif // PG_VERSION_NUM >= 90000



} // extern "C"

#undef typeid


In plv8_param.cc, replace following:
extern "C" {



#include "catalog/pg_type.h"

#include "utils/builtins.h"

#include "utils/lsyscache.h"



} // extern "C"


with
#define typeid __typeid

extern "C" {



#include "catalog/pg_type.h"

#include "utils/builtins.h"

#include "utils/lsyscache.h"



} // extern "C"

#undef typeid


After making the above changes, you will be able to compile PLV8 with Advanced Server as shown below:
[root@localhost plv8js]# make

sed -e 's/^#undef PLV8_VERSION/#define PLV8_VERSION "1.5.0-dev1"/' plv8_config.h.in > plv8_config.h

g++ -Wall -O2 -DV8_USE_UNSAFE_HANDLES  -I. -I./ -I/usr/ppas-9.4/include/server -I/usr/ppas-9.4/include/internal -I/usr/include/et -D_GNU_SOURCE -I/usr/include/libxml2  -I/usr/include -fPIC -c -o plv8.o plv8.cc

g++ -Wall -O2 -DV8_USE_UNSAFE_HANDLES  -I. -I./ -I/usr/ppas-9.4/include/server -I/usr/ppas-9.4/include/internal -I/usr/include/et -D_GNU_SOURCE -I/usr/include/libxml2  -I/usr/include -fPIC -c -o plv8_type.o plv8_type.cc

g++ -Wall -O2 -DV8_USE_UNSAFE_HANDLES  -I. -I./ -I/usr/ppas-9.4/include/server -I/usr/ppas-9.4/include/internal -I/usr/include/et -D_GNU_SOURCE -I/usr/include/libxml2  -I/usr/include -fPIC -c -o plv8_func.o plv8_func.cc

g++ -Wall -O2 -DV8_USE_UNSAFE_HANDLES  -I. -I./ -I/usr/ppas-9.4/include/server -I/usr/ppas-9.4/include/internal -I/usr/include/et -D_GNU_SOURCE -I/usr/include/libxml2  -I/usr/include -fPIC -c -o plv8_param.o plv8_param.cc

echo "extern const unsigned char coffee_script_binary_data[] = {" >coffee-script.cc

(od -txC -v coffee-script.js | \

 sed -e "s/^[0-9]*//" -e s"/ \([0-9a-f][0-9a-f]\)/0x\1,/g" -e"\$d" ) >>coffee-script.cc

echo "0x00};" >>coffee-script.cc

g++ -Wall -O2 -DV8_USE_UNSAFE_HANDLES  -I. -I./ -I/usr/ppas-9.4/include/server -I/usr/ppas-9.4/include/internal -I/usr/include/et -D_GNU_SOURCE -I/usr/include/libxml2  -I/usr/include -fPIC -c -o coffee-script.o coffee-script.cc

echo "extern const unsigned char livescript_binary_data[] = {" >livescript.cc

(od -txC -v livescript.js | \

 sed -e "s/^[0-9]*//" -e s"/ \([0-9a-f][0-9a-f]\)/0x\1,/g" -e"\$d" ) >>livescript.cc

echo "0x00};" >>livescript.cc

g++ -Wall -O2 -DV8_USE_UNSAFE_HANDLES  -I. -I./ -I/usr/ppas-9.4/include/server -I/usr/ppas-9.4/include/internal -I/usr/include/et -D_GNU_SOURCE -I/usr/include/libxml2  -I/usr/include -fPIC -c -o livescript.o livescript.cc

g++ -O2 -g -pipe -Wall -Wp,-D_FORTIFY_SOURCE=2 -fexceptions -fstack-protector --param=ssp-buffer-size=4 -m64 -mtune=generic -I/usr/include/et -Wall -Wmissing-prototypes -Wpointer-arith -Wdeclaration-after-statement -Wendif-labels -Wmissing-format-attribute -Wformat-security -fno-strict-aliasing -fwrapv -fpic -shared -o plv8.so plv8.o plv8_type.o plv8_func.o plv8_param.o coffee-script.o livescript.o -L/usr/ppas-9.4/lib -L/usr/lib64 -Wl,--as-needed -Wl,-rpath,'/usr/ppas-9.4/lib',--enable-new-dtags  -lv8

sed -e 's/@PLV8_VERSION@/1.5.0-dev1/g' plv8.control.common | g++ -E -P -DLANG_plv8 - > plv8.control

sed -e 's/@LANG_NAME@/plv8/g' plv8.sql.common | g++ -E -P -I. -I./ -I/usr/ppas-9.4/include/server -I/usr/ppas-9.4/include/internal -I/usr/include/et -D_GNU_SOURCE -I/usr/include/libxml2  -I/usr/include -DLANG_plv8 - > plv8--1.5.0-dev1.sql

sed -e 's/@PLV8_VERSION@/1.5.0-dev1/g' plv8.control.common | g++ -E -P -DLANG_plcoffee - > plcoffee.control

sed -e 's/@LANG_NAME@/plcoffee/g' plv8.sql.common | g++ -E -P -I. -I./ -I/usr/ppas-9.4/include/server -I/usr/ppas-9.4/include/internal -I/usr/include/et -D_GNU_SOURCE -I/usr/include/libxml2  -I/usr/include -DLANG_plcoffee - > plcoffee--1.5.0-dev1.sql

sed -e 's/@PLV8_VERSION@/1.5.0-dev1/g' plv8.control.common | g++ -E -P -DLANG_plls - > plls.control

sed -e 's/@LANG_NAME@/plls/g' plv8.sql.common | g++ -E -P -I. -I./ -I/usr/ppas-9.4/include/server -I/usr/ppas-9.4/include/internal -I/usr/include/et -D_GNU_SOURCE -I/usr/include/libxml2  -I/usr/include -DLANG_plls - > plls--1.5.0-dev1.sql


/bin/mkdir -p '/usr/ppas-9.4/lib'

/bin/mkdir -p '/usr/ppas-9.4/share/extension'

/bin/mkdir -p '/usr/ppas-9.4/share/extension'

/usr/bin/install -c -m 755  plv8.so '/usr/ppas-9.4/lib/plv8.so'

/usr/bin/install -c -m 644 plv8.control '/usr/ppas-9.4/share/extension/'

/usr/bin/install -c -m 644 plv8.control plv8--1.5.0-dev1.sql plcoffee.control plcoffee--1.5.0-dev1.sql plls.control plls--1.5.0-dev1.sql '/usr/ppas-9.4/share/extension/'


After compiling PLV8, you now can install the PLV8 language in Advanced Server using the following command:

beta=# CREATE EXTENSION PLV8;

CREATE EXTENSION

beta=#


To test your installed PLV8, here is some sample code:
beta=# DO $$ PLV8.elog(NOTICE, 'this', 'is', 'inline', 'code') $$ LANGUAGE PLV8;

NOTICE:  this is inline code

DO



beta=# CREATE TYPE rec AS (i integer, t text);

CREATE TYPE

beta=# CREATE FUNCTION set_of_records() RETURNS SETOF rec AS

beta-# $$

beta$#     // PLV8.return_next() stores records in an internal tuplestore,

beta$#     // and return all of them at the end of function.

beta$#     PLV8.return_next( { "i": 1, "t": "a" } );

beta$#     PLV8.return_next( { "i": 2, "t": "b" } );

beta$#

beta$#     // You can also return records with an array of JSON.

beta$#     return [ { "i": 3, "t": "c" }, { "i": 4, "t": "d" } ];

beta$# $$

beta-# LANGUAGE PLV8;

CREATE FUNCTION

beta=# SELECT * FROM set_of_records();

 i | t

---+---

 1 | a

 2 | b

 3 | c

 4 | d

(4 rows)




In case you need a patched version of PLV8, use the following git repository:
 https://github.com/vibhorkum/PLV8_FOR_PPAS.git PLV8_ppas


To use this, execute the following command:
 git clone https://github.com/vibhorkum/PLV8_FOR_PPAS.git PLV8_ppas

cd PLV8_ppas

make

make install


To test the compiled PLV8, you can use the following command:
[root@localhost plv8js]# make installcheck

/usr/ppas-9.4/lib/pgxs/src/makefiles/../../src/test/regress/pg_regress --inputdir=./ --psqldir='/usr/ppas-9.4/bin'    --dbname=contrib_regression init-extension plv8 inline json startup_pre startup varparam json_conv window dialect

(using postmaster on Unix socket, port 5444)

============== dropping database "contrib_regression" ==============

DROP DATABASE

============== creating database "contrib_regression" ==============

CREATE DATABASE

ALTER DATABASE

============== running regression test queries        ==============

test init-extension           ... ok

test plv8                     ... ok

test inline                   ... ok

test json                     ... ok

test startup_pre              ... ok

test startup                  ... ok

test varparam                 ... ok

test json_conv                ... ok

test window                   ... ok

test dialect                  ... ok



======================

 All 10 tests passed.

======================