Monday, February 13, 2012

Partition Syntax Support in PPAS 9.1

In Series of New Features in Advanced Server 9.1, today I tought to write about Parition Table Syntax Supported in PPAS. In PostgreSQL and till PPAS 9.0, user has to follow method given below for partitioning a table:
1. CREATE PARENT Table,
2. Create Child tables using Inherit feature
3. Create Trigger on Partition on Parent, so that it can re-direct insert to Right Partition.
4. And if user has to add new child table, then it has to do 2 and 3 steps again.


Now, in PPAS 9.0, user doesn't have to perform above activities. PPAS 9.0 supports PARTITION TABLE syntax.

Lets see how PARTITION syntax in PPAS can make users/DBAs life easier.

We know that PPAS/PostgreSQL supports two types of partition (Range and List). So, we will see how its simple with CREATE PARTITION SYNTAX.
Lets CREATE RANGE PARTITION as we used to do in PPAS 9.0/PostgreSQL
1. Create Master table as given below:
CREATE TABLE partition_master(id numeric primary key,val text);
CREATE TABLE partition_child1(CHECK (id > 0 and id <=10)) inherits(partition_master);
CREATE TABLE partition_child2(CHECK (id >10 and id <=20)) inherits(partition_master);
2. Then create check constriants on Both Child tables
alter table partition_child1 add primary key (id);
alter table partition_child2 add primary key (id);
3. Then Create Trigger, which redirect Inserts to right master:
CREATE OR REPLACE FUNCTION part_trig_insrt() RETURNS trigger
AS
$$
BEGIN
   IF TG_OP='INSERT' THEN
      IF NEW.id >0 and NEW.id <=10 THEN
           INSERT INTO partition_child1 VALUES(NEW.*);
      ELSIF NEW.id >10 and NEW.id <=20 THEN
           INSERT INTO partition_child2 VALUES(NEW.*);
      ELSE
          RAISE 'inserted partition key doesnt map to any partition';      
     END IF;
  END IF;
END;
$$ language plpgsql;
CREATE TRIGGER partition_trig_insert BEFORE INSERT ON partition_master FOR EACH ROW execute procedure part_trig_insrt();
similarly you have to write trigger which can handle partition key update. And wheneven you want to add new partition update the trigger function and create new partition table etc. Now, in 9.1AS on-wards, user can run single command for partition and PPAS will take care of all things as given below:
CREATE TABLE partition_master (id numeric primary key,val text)
PARTITION BY RANGE(id)
(PARTITION partition_child1 VALUES LESS THAN (11),
PARTITION partition_child2 VALUES LESS THAN (21));

edb=# insert into partition_master values(1,'First');
INSERT 0 0
edb=# insert into partition_master values(11,'Eleventh');
INSERT 0 0
edb=# select * from partition_master;
 id |   val    
----+----------
  1 | First
 11 | Eleventh
(2 rows)

edb=# select * from only partition_master_partition_child1;
 id |  val  
----+-------
  1 | First
(1 row)

edb=# select * from partition_master_partition_child2;
 id |   val    
----+----------
 11 | Eleventh
(1 row)
That was easy. With single command you can have your partition table in PPAS. Suppose later, user wants to add one more partition then he can execute following single command:
ALTER TABLE partition_master add partition partition_child3 VALUES LESS THAN (31);

edb=# insert into partition_master values(30,'Thirty');
INSERT 0 0
edb=# select * from partition_master;
 id |   val    
----+----------
  1 | First
 11 | Eleventh
 30 | Thirty
(3 rows)

edb=# select * from partition_master_partition_child3;
 id |  val   
----+--------
 30 | Thirty
(1 row)
Thats simple. isn't? With this PPAS 9.1 Partition Syntax also allows swaping an existing table with a partition or subpartition, as given below:
CREATE TABLE single_table (id numeric primary key,val text)
insert into single_master select generate_series(1,10);
INSERT 0 10

ALTER TABLE partition_master 
EXCHANGE PARTITION partition_child1
WITH TABLE single_table;
Other syntax which are supported is given below:
1.  ALTER TABLE… ADD PARTITION
2.  ALTER TABLE… ADD SUBPARTITION
3.  ALTER TABLE… DROP PARTITION
4.  ALTER TABLE… DROP SUBPARTITION
5.  ALTER TABLE… SPLIT PARTITION
6.  ALTER TABLE… SPLIT SUBPARTITION
7.  ALTER TABLE… TRUNCATE PARTITION
8.  ALTER TABLE… TRUNCATE SUBPARTITION
9.  ALTER TABLE… EXCHANGE PARTITION
10. ALTER TABLE… MOVE PARTITION
11. ALTER TABLE… RENAME PARTITION
Support of above partition syntaxes have really made management of partition table easier in PPAS 9.1!

Friday, February 10, 2012

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!!