Leaving the History Behind with Oracle's Fine Grained Access Control - Page 2

January 24, 2003

c.) Fine Grained Access Control ( FGAC)

Two new features of Oracle8i release 8.1 are Fine Grained Access Controls and Secure Application Contexts. There has been considerable confusion regarding the naming of these new features.

Synonyms used so far:

  • Fine Grained Access Control (technical name)
  • Virtual Private Database (marketing name)
  • Row Level Security (technical name based on the PL/SQL packages that implement this feature)

From Oracle documentation:

"Fine Grained Access Control in Oracle8i is the ability for you to dynamically attach, at runtime, a predicate (where clause) to any and all queries issued against a database table or view. You now have the ability to procedurally modify the query at runtime. You may evaluate who is running the query, where they are running the query from, when they are running the query and develop a predicate given those circumstances. With the use of Application Contexts, your may securely add additional information to the environment (such as an application role the user may have) and access this in your procedure or predicate as well."

For our export test we are going to mask some tables from user.
Please take care that you use this approach only if your database supports the FGAC option.
The Standard Edition does not include the FGAC option, and it will not work. You have full support in the Enterprise Edition and the Personal Edition.

First we have to create a function and then a policy for the ARTIST user.

SQL> connect artist/artist@dba.world
Connected.

In schema ARTIST, create a function "skip_artist_table" which will return predicate, with condition checking (1=2).

The result is always false, so rows are never returned to ARTIST.

SQL> CREATE or REPLACE FUNCTION skip_artist_table (tbl_schema VARCHAR2, tbl_name VARCHAR2)
  2     RETURN VARCHAR2 IS usr_context VARCHAR2(2000);
  3     BEGIN
  4      if sys_context ('USERENV', 'SESSION_USER') = 'ARTIST' THEN usr_context := '1=2';
  5      else 
  6       usr_context := '';
  7      end if;
  8      RETURN usr_context;
  9  END skip_artist_table;
 10  /

Function created.

SQL> select skip_artist_table('dummy','dummy') from dual;

SKIP_ARTIST_TABLE('DUMMY','DUMMY')
---------------------------------------------------------------
1=2

Next, we need to check the tables.

SQL> connect artist/artist@dba.world
Connected.

SQL> select count(*) from TRANSFER;

  COUNT(*)
----------
     10000
SQL> select count(*) from INPUT;

  COUNT(*)
----------
     10000

The next step is to add Policy for each table that we want to skip. We are using add_policy procedure from Oracle dbms_rls package:

SQL> execute dbms_rls.add_policy 
('ARTIST','TRANSFER','SKIP_TRANSFER','ARTIST','SKIP_ARTIST_TABLE');

PL/SQL procedure successfully completed.

SQL> execute dbms_rls.add_policy 
('ARTIST','INPUT','SKIP_INPUT','ARTIST','SKIP_ARTIST_TABLE');

PL/SQL procedure successfully completed.

SQL> select count(*) from TRANSFER;

  COUNT(*)
----------
         0

SQL> select count(*) from INPUT;

  COUNT(*)
----------
         0

We're ready to make an export and compare results.

. about to export ARTIST's tables via Conventional Path ...
. . exporting table                  BACKUP_STATUS        411 rows exported
. . exporting table              CRITICAL_SEGMENTS          0 rows exported
EXP-00079: Data in table "INPUT" is protected. 
Conventional path may only be exporting partial table.
. . exporting table                          INPUT          0 rows exported
. . exporting table                     PLAN_TABLE         13 rows exported
EXP-00079: Data in table "TRANSFER" is protected. 
Conventional path may only be exporting partial table.
. . exporting table                       TRANSFER          0 rows exported
. . exporting table                     TS_STORAGE      25334 rows exported

To get rid of masking:

SQL> connect artist/artist@dba.world
Connected.
SQL>  execute dbms_rls.drop_policy('ARTIST','TRANSFER','SKIP_TRANSFER');

PL/SQL procedure successfully completed.

SQL> execute dbms_rls.drop_policy('ARTIST','INPUT','SKIP_INPUT');

PL/SQL procedure successfully completed.

SQL> select count(*) from TRANSFER;

  COUNT(*)
----------
     10000
SQL> select count(*) from INPUT;

  COUNT(*)
----------
     10000

This small UNIX script can handle the task of dynamically adding policy, exporting users' tables, and dropping policy after export.

Summary

This article shows some techniques to avoid the Oracle database utility limitation. Export is one of the great tools and DBAs should know their limitations. Oracle is developing in such a way that we can expect a solution for tricks we used in version 10i. Anyway, we've touched on some lovely features, like FGAC database, that are not well known but used throughout Europe in the banking sector. So DBAs, be prepared for more surprises.

» See All Articles by Columnist Marin Komadina








The Network for Technology Professionals

Search:

About Internet.com

Legal Notices, Licensing, Permissions, Privacy Policy.
Advertise | Newsletters | E-mail Offers