Oracle® Database Security Guide 11g Release 2 (11.2) Part Number E10574-02 |
|
|
View PDF |
This chapter contains:
Tutorials: Creating Oracle Virtual Private Database Policies
How Oracle Virtual Private Database Works with Other Oracle Features
Finding Information About Oracle Virtual Private Database Policies
This section contains:
Which Privileges Are Used to Run Oracle Virtual Private Database Policy Functions?
Using Oracle Virtual Private Database with an Application Context
Oracle Virtual Private Database (VPD) enables you to create security policies to control database access at the row and column level. Essentially, Oracle Virtual Private Database adds a dynamic WHERE
clause to a SQL statement that is issued against the table, view, or synonym to which an Oracle Virtual Private Database security policy was applied.
Oracle Virtual Private Database enforces security, to a fine level of granularity, directly on database tables, views, or synonyms. Because you attach security policies directly to these database objects, and the policies are automatically applied whenever a user accesses data, there is no way to bypass security.
When a user directly or indirectly accesses a table, view, or synonym that is protected with an Oracle Virtual Private Database policy, Oracle Database dynamically modifies the SQL statement of the user. This modification creates a WHERE
condition (called a predicate) returned by a function implementing the security policy. Oracle Database modifies the statement dynamically, transparently to the user, using any condition that can be expressed in or returned by a function. You can apply Oracle Virtual Private Database policies to SELECT
, INSERT
, UPDATE
, INDEX
, and DELETE
statements.
For example, suppose a user performs the following query:
SELECT * FROM OE.ORDERS;
The Oracle Virtual Private Database policy dynamically appends the statement with a WHERE
clause. For example:
SELECT * FROM OE.ORDERS WHERE SALES_REP_ID = 159;
In this example, the user can only view orders by Sales Representative 159.
If you want to filter the user based on the session information of that user, such as the ID of the user, you can create the WHERE
clause to use an application context. For example:
SELECT * FROM OE.ORDERS WHERE SALES_REP_ID = SYS_CONTEXT('USERENV','SESSION_USER');
Note:
Oracle Virtual Private Database does not support filtering for DDLs, such asTRUNCATE
or ALTER TABLE
statements.Oracle Virtual Private Database policies provide the following benefits:
Attaching Oracle Virtual Private Database security policies to database tables, views, or synonyms, rather than implementing access controls in all your applications, provides the following benefits:
Security. Associating a policy with a database table, view, or synonym can solve a potentially serious application security problem. Suppose a user is authorized to use an application, and then drawing on the privileges associated with that application, wrongfully modifies the database by using an ad hoc query tool, such as SQL*Plus. By attaching security policies directly to tables, views, or synonyms, fine-grained access control ensures that the same security is in force, no matter how a user accesses the data.
Simplicity. You add the security policy to a table, view, or synonym only once, rather than repeatedly adding it to each of your table-based, view-based, or synonym-based applications.
Flexibility. You can have one security policy for SELECT
statements, another for INSERT
statements, and still others for UPDATE
and DELETE
statements. For example, you might want to enable Human Resources clerks to have SELECT
privileges for all employee records in their division, but to update only salaries for those employees in their division whose last names begin with A
through F
. Furthermore, you can create multiple policies for each table, view, or synonym.
Running policy functions multiple times can affect performance. You can control the performance of policy functions by configuring how Oracle Database caches the Oracle Virtual Private Database predicates. The following options are available:
Evaluate the policy once for each query (static policies).
Evaluate the policy only when an application context within the policy function changes (context-sensitive policies).
Evaluate the policy each time it is run (dynamic policies).
See "Optimizing Performance by Using Oracle Virtual Private Database Policy Types" for information configuring these policy types.
For greater security, the Oracle Virtual Private Database policy function runs as if it had been declared with definer's rights. Do not declare it as invoker's rights because this can confuse yourself and other users who maintain the code.
See Also:
Oracle Database PL/SQL Language Reference for detailed information about definer's rightsYou can use application contexts with Oracle Virtual Private Database policies. When you create an application context, it securely caches user information. Only the designated application package can set the cached environment. It cannot be changed by the user or outside the package. In addition, because the data is cached, performance is increased. Chapter 6, "Using Application Contexts to Retrieve User Information" describes application contexts in detail.
For example, suppose you want to base access to the ORDERS_TAB
table on the customer ID number. Rather than querying the customer ID number for a logged-in user each time you need it, you could store the number in the application context. Then, the customer number is available in the session when you need it.
Application contexts are especially helpful if your security policy is based on multiple security attributes. For example, if a policy function bases a WHERE
predicate on four attributes (such as employee number, cost center, position, spending limit), then multiple subqueries must execute to retrieve this information. Instead, if this data is available through an application context, then performance is much faster.
You can use an application context to return the correct security policy, enforced through a predicate. For example, consider an order entry application that enforces the following rules: customers only see their own orders, and clerks see all orders for all customers. These are two different policies. You could define an application context with a position
attribute, and this attribute could be accessed within the policy function to return the correct predicate, depending on the value of the attribute. Thus, you can enable a user in the clerk
position to retrieve all orders, but a user in the customer
position can see only those records associated with that particular user.
To design a fine-grained access control policy that returns a specific predicate for an attribute, you need to access the application context within the function that implements the policy. For example, suppose you want to limit customers to seeing only their own records. The user performs the following query:
SELECT * FROM orders_tab
Fine-grained access control dynamically modifies this query to include the following WHERE
predicate:
SELECT * FROM orders_tab WHERE custno = SYS_CONTEXT ('order_entry', 'cust_num');
Continuing with the preceding example, suppose you have 50,000 customers, and you do not want to have a different predicate returned for each customer. Customers all share the same WHERE
predicate, which prescribes that they can only see their own orders. It is merely their customer numbers that are different.
Using application context, you can return one WHERE
predicate within a policy function that applies to 50,000 customers. As a result, there is one shared cursor that executes differently for each customer, because the customer number is evaluated at execution time. This value is different for every customer. Use of application context in this case provides optimum performance, and at row-level security.
The SYS_CONTEXT
function works much like a bind variable; only the SYS_CONTEXT
arguments are constants.
To implement Oracle Virtual Private Database, you must create a function to generate the dynamic WHERE
clause, and a policy to attach this function to the objects that you want to protect.
See Also:
To generate the dynamic WHERE
clause (predicate), you must create a function (not a procedure) that defines the restrictions that you want to enforce. Usually, the security administrator creates this function in his or her own schema. For more complex behavior, such as including calls to other functions or adding checks to track failed logon attempts, create these functions within a package.
The function must have the following behavior:
It must take as arguments a schema name and an object (table, view, or synonym) name as inputs. Define input parameters to hold this information, but do not specify the schema and object name themselves within the function. The policy that you create with the DBMS_RLS
package (described in "Creating a Policy to Attach the Function to the Objects You Want to Protect") provides the names of the schema, and object to which the policy will apply. You must create the parameter for the schema first, followed by the parameter for the object.
It must provide a return value for the WHERE clause predicate that will be generated. The return value for the WHERE
clause is always a VARCHAR2
data type.
It must generate a valid WHERE clause. This code can be as basic as the example in "Tutorial: Creating a Simple Oracle Virtual Private Database Policy", in that its WHERE
clause is the same for all users who log on.
But in most cases, you may want to design the WHERE
clause to be different for each user, each group of users, or each application that accesses the objects you want to protect. For example, if a manager logs in, the WHERE
clause can be specific to the rights of that particular manager. You can do this by incorporating an application context, which accesses user session information, into the WHERE
clause generation code. "Tutorial: Implementing a Policy with a Database Session-Based Application Context" demonstrates how to create an Oracle Virtual Private Database policy that uses an application context.
You can create Oracle Virtual Private Database functions that do not use an application context, but an application context creates a much stronger Oracle Virtual Private Database policy, by securely basing user access on the session attributes of that user, such as the user ID. Chapter 6, "Using Application Contexts to Retrieve User Information" discusses different types of application contexts in detail.
In addition, you can embed C or Java calls to access operating system information or to return WHERE
clauses from an operating system file or other source.
Note:
If you plan to run the function across different editions, you can control the results of the function: whether the results are uniform across all editions, or specific to the edition in which the function is run. See "How Editions Affects the Results of a Global Application Context PL/SQL Package" for more information.After you create the function, you need to create an Oracle Virtual Private Database policy that associates the function with a table, view, or synonym. You create the policy by using the DBMS_RLS
package. If you are not SYS
, then you must be granted EXECUTE
privileges to use the DBMS_RLS
package. This package contains procedures that enable you to manage the policy and set fine-grained access control. For example, to attach the policy to a table, you use the DBMS_RLS.ADD_POLICY
procedure. Within this setting, you set fine-grained access control, such as setting the policy to go into effect when a user issues a SELECT
or UPDATE
statement on the table or view.
The combination of creating the function and then applying it to a table or view is referred to as creating the Oracle Virtual Private Database policy.
"Tutorials: Creating Oracle Virtual Private Database Policies" provides examples of how to create Virtual Private Database policies. See "Configuring an Oracle Virtual Private Database Policy" for detailed information.
After you create a function that defines the actions of the Oracle Virtual Private Database WHERE
clause, you need to associate this function with the database table to which the VPD action applies. You can do this by configuring an Oracle Virtual Private Database policy. The policy itself is a mechanism for managing the Virtual Private Database function. The policy also enables you to add fine-grained access control, such as specifying the types of SQL statements or particular table columns the policy affects. When a user tries to access the data in this database object, the policy goes into effect automatically.
This section describes commonly used ways of attaching policies to tables, views, and synonyms. To manage an Oracle Virtual Private Database policy, you use the DBMS_RLS
package, which is described in detail in Oracle Database PL/SQL Packages and Types Reference.
Table 7-1 lists the procedures in the DBMS_RLS
package.
Table 7-1 DBMS_RLS Procedures
Procedure | Description |
---|---|
For Handling Individual Policies |
|
Adds a policy to a table, view, or synonym |
|
Enables (or disables) a policy you previously added to a table, view, or synonym |
|
Invalidates cursors associated with nonstatic policies |
|
To drop a policy from a table, view, or synonym |
|
For Handling Grouped Policies |
|
Creates a policy group |
|
Drops a policy group |
|
Adds a policy to the specified policy group |
|
Enables a policy within a group |
|
Parses again the SQL statements associated with a refreshed policy |
|
Disables a policy within a group |
|
Drops a policy that is a member of the specified group |
|
For Handling Application Contexts |
|
Adds the context for the active application |
|
Drops the context for the application |
See Also:
"Components of an Oracle Virtual Private Database Policy" for a description of the type of function that you need to create to control user access to a database table, view, or synonym
Chapter 6, "Using Application Contexts to Retrieve User Information" if you plan to use application contexts in the Oracle Virtual Private Database policy (which in most cases, you would)
"Tutorials: Creating Oracle Virtual Private Database Policies" for examples of using application contexts in sample Oracle Virtual Private Database functions
To attach a policy to a table, view, or synonym, you use the DBMS_RLS.ADD_POLICY
procedure. You need to specify the table, view, or synonym to which you are adding a policy, and a name for the policy. You can also specify other information, such as the types of statements the policy controls (SELECT
, INSERT
, UPDATE
, DELETE
, CREATE INDEX
, or ALTER INDEX
).
Example 7-1 shows how to use DBMS_RLS.ADD_POLICY
to attach an Oracle Virtual Private Database policy called secure_update
to the HR.EMPLOYEES
table. The function attached to the policy is check_updates
.
Example 7-1 Attaching a Simple Oracle Virtual Private Database Policy to a Table
BEGIN DBMS_RLS.ADD_POLICY( object_schema => 'hr', object_name => 'employees', policy_name => 'secure_update', policy_function => 'check_updates', ...
If the function was created inside a package, include the package name. For example:
policy_function => 'pkg.check_updates', ...
Note:
Although you can define a policy against a table, you cannot select that table from within the policy that was defined against the table.You can enforce Oracle Virtual Private Database policies for SELECT
, INSERT
, UPDATE
, INDEX
, and DELETE
statements. If you do not specify a statement type, by default, Oracle Database specifies SELECT
, INSERT
, UPDATE
, and DELETE
, but not INDEX
. Enter any combination of these statement types by using the statement_types
parameter in the DBMS_RLS.ADD_POLICY
procedure. Enclose the list in a pair of single quotation marks.
Example 7-2 shows an how to use the statement_types
parameter to specify the SELECT
and INDEX
statements for a policy.
Example 7-2 Specifying SQL Statement Types with DBMS_RLS.ADD_POLICY
BEGIN
DBMS_RLS.ADD_POLICY(
object_schema => 'hr',
object_name => 'employees',
policy_name => 'secure_update',
policy_function => 'check_updates',
statement_types => 'SELECT,INDEX');
END;
/
Important:
Be aware that a user who has privileges to maintain an index can see all the row data, even if the user does not have full table access under a regular query such asSELECT
. For example, a user can create a function-based index that contains a user-defined function with column values as its arguments. During index creation, Oracle Database passes column values of every row into the user function, making the row data available to the user who creates the index. You can enforce Oracle Virtual Private Database policies on index maintenance operations by specifying INDEX
with the statement_types
parameter.You can create policies that enforce row-level security when a security-relevant column is referenced in a query.
Adding Policies for Column-Level Oracle Virtual Private Database
Using Column Masking to Display Sensitive Columns as NULL Values
Column-level policies enforce row-level security when a query references a security-relevant column. You can apply a column-level Oracle Virtual Private Database policy to tables and views, but not to synonyms.
To apply the policy to a column, specify the security-relevant column by using the sec_relevant_cols
parameter of the DBMS_RLS.ADD_POLICY
procedure. This parameter applies the security policy whenever the column is referenced, explicitly or implicitly, in a query.
For example, users who are not in a Human Resources department typically are allowed to view only their own Social Security numbers. A sales clerk initiates the following query:
SELECT fname, lname, ssn FROM emp;
The function implementing the security policy returns the predicate ssn='my_ssn
'. Oracle Database rewrites the query and executes the following:
SELECT fname, lname, ssn FROM emp WHERE ssn = 'my_ssn';
Example 7-3 shows a Oracle Virtual Private Database policy in which sales department users cannot see the salaries of people outside the department (department number 30) of the sales department users. The relevant columns for this policy are sal
and comm
. First, the Oracle Virtual Private Database policy function is created, and then it is added by using the DBMS_RLS
PL/SQL package.
Example 7-3 Creating a Column-Level Oracle Virtual Private Database Policy
CREATE OR REPLACE FUNCTION hide_sal_comm ( v_schema IN VARCHAR2, v_objname IN VARCHAR2) RETURN VARCHAR2 AS con VARCHAR2 (200); BEGIN con := 'deptno=30'; RETURN (con); END hide_sal_comm;
Then you configure the policy with the DBMS_RLS.ADD_POLICY
procedure as follows:
BEGIN
DBMS_RLS.ADD_POLICY (
object_schema => 'scott',
object_name => 'emp',
policy_name => 'hide_sal_policy',
policy_function => 'hide_sal_comm',
sec_relevant_cols => 'sal,comm');
END;
The default behavior for column-level Oracle Virtual Private Database is to restrict the number of rows returned for a query that references columns containing sensitive information. You specify these security-relevant columns by using the sec_relevant_columns
parameter of the DBMS_RLS.ADD_POLICY
procedure, as shown in Example 7-3.
For example, consider sales department users with the SELECT
privilege on the emp
table, which is protected with the column-level Oracle Virtual Private Database policy created in Example 7-3. The user (for example, user SCOTT
) runs the following query:
SELECT ENAME, d.dname, JOB, SAL, COMM FROM emp e, dept d WHERE d.deptno = e.deptno;
The database returns the following rows:
ENAME DNAME JOB SAL COMM ---------- -------------- --------- ---------- ---------- ALLEN SALES SALESMAN 1600 300 WARD SALES SALESMAN 1250 500 MARTIN SALES SALESMAN 1250 1400 BLAKE SALES MANAGER 2850 TURNER SALES SALESMAN 1500 0 JAMES SALES CLERK 950 6 rows selected.
The only rows that are displayed are those that the user has privileges to access all columns in the row.
If a query references a sensitive column, then the default action of column-level Oracle Virtual Private Database restricts the number of rows returned. With column-masking behavior, all rows display, even those that reference sensitive columns. However, the sensitive columns display as NULL
values. To enable column-masking, set the sec_relevant_cols_opt
parameter of the DBMS_RLS.ADD_POLICY
procedure.
For example, consider the results of the sales clerk query, described in the previous example. If column-masking is used, then instead of seeing only the row containing the details and Social Security number of the sales clerk, the clerk would see all rows from the emp
table, but the ssn
column values would be returned as NULL
. Note that this behavior is fundamentally different from all other types of Oracle Virtual Private Database policies, which return only a subset of rows.
In contrast to the default action of column-level Oracle Virtual Private Database, column-masking displays all rows, but returns sensitive column values as NULL
. To include column-masking in your policy, set the sec_relevant_cols_opt
parameter of the DBMS_RLS.ADD_POLICY
procedure to dbms_rls.ALL_ROWS
.
Example 7-4 shows column-level Oracle Virtual Private Database column-masking. It uses the same VPD policy as Example 7-3, but with sec_relevant_cols_opt
specified as dbms_rls.ALL_ROWS
.
Example 7-4 Adding a Column Masking to an Oracle Virtual Private Database Policy
BEGIN DBMS_RLS.ADD_POLICY( object_schema => 'scott', object_name => 'emp', policy_name => 'hide_sal_policy', policy_function => 'hide_sal_comm', sec_relevant_cols =>' sal,comm', sec_relevant_cols_opt => dbms_rls.ALL_ROWS); END;
Assume that a sales department user with SELECT
privilege on the emp
table (such as user SCOTT
) runs the following query:
SELECT ENAME, d.dname, job, sal, comm FROM emp e, dept d WHERE d.deptno = e.deptno;
The database returns all rows specified in the query, but with certain values masked because of the Oracle Virtual Private Database policy:
ENAME DNAME JOB SAL COMM ---------- -------------- --------- ---------- ---------- CLARK ACCOUNTING MANAGER KING ACCOUNTING PRESIDENT MILLER ACCOUNTING CLERK JONES RESEARCH MANAGER FORD RESEARCH ANALYST ADAMS RESEARCH CLERK SMITH RESEARCH CLERK SCOTT RESEARCH ANALYST WARD SALES SALESMAN 1250 500 TURNER SALES SALESMAN 1500 0 ALLEN SALES SALESMAN 1600 300 JAMES SALES CLERK 950 BLAKE SALES MANAGER 2850 MARTIN SALES SALESMAN 1250 1400 14 rows selected.
The column-masking returned all rows requested by the sales user query, but made the sal
and comm
columns NULL
for employees outside the sales department.
Column-masking applies only to SELECT
statements.
Column-masking conditions generated by the policy function must be simple Boolean expressions, unlike regular Oracle Virtual Private Database predicates.
For applications that perform calculations, or do not expect NULL
values, use standard column-level Oracle Virtual Private Database, specifying sec_relevant_cols
rather than the sec_relevant_cols_opt
column-masking option.
Column-masking used with UPDATE AS SELECT
updates only the columns that users are allowed to see.
For some queries, column-masking may prevent some rows from displaying. For example:
SELECT * FROM emp WHERE sal = 10;
Because the column-masking option was set, this query may not return rows if the salary
column returns a NULL
value.
This section contains:
Designating a Default Policy Group with the SYS_DEFAULT Policy Group
Establishing Multiple Policies for Each Table, View, or Synonym
You can group multiple security policies together, and apply them to an application. A policy group is a set of security policies that belong to an application. You can designate an application context (known as a driving context or policy context) to indicate the policy group in effect. Then, when a user accesses the table, view, or synonym column, Oracle Database looks up the driving context to determine the policy group in effect. It enforces all the associated policies that belong to the policy group.
Policy groups are useful for situations where multiple applications with multiple security policies share the same table, view, or synonym. This enables you to identify those policies that should be in effect when the table, view, or synonym is accessed.
For example, in a hosting environment, Company A can host the BENEFIT
table for Company B and Company C. The table is accessed by two different applications, Human Resources and Finance, with two different security policies. The Human Resources application authorizes users based on ranking in the company, and the Finance application authorizes users based on department. Integrating these two policies into the BENEFIT
table requires joint development of policies between the two companies, which is not a feasible option. By defining an application context to drive the enforcement of a particular set of policies to the base objects, each application can implement a private set of security policies.
To do this, you organize security policies into groups. By referring to the application context, Oracle Database determines which group of policies should be in effect at run time. The server enforces all the policies that belong to that policy group.
To add a policy to a table, view, or synonym, use the DBMS_RLS.ADD_GROUPED_POLICY
procedure to specify the group to which the policy belongs. To specify which policies will be effective, you can add a driving context using the DBMS_RLS.ADD_POLICY_CONTEXT
procedure. If the driving context returns an unknown policy group, then an error is returned.
If the driving context is not defined, then Oracle Database runs all policies. Likewise, if the driving context is NULL
, then policies from all policy groups are enforced. An application accessing the data cannot bypass the security setup module (which sets up application context) to avoid any applicable policies.
You can apply multiple driving contexts to the same table, view, or synonym, and each of them will be processed individually. This enables you to configure multiple active sets of policies to be enforced.
Consider, for example, a hosting company that hosts Benefits and Financial applications, which share some database objects. Both applications are striped for hosting using a SUBSCRIBER
policy in the SYS_DEFAULT
policy group. Data access is partitioned first by subscriber ID, then by whether the user is accessing the Benefits or Financial applications (determined by a driving context). Suppose that Company A, which uses the hosting services, wants to apply a custom policy that relates only to its own data access. You could add an additional driving context (such as COMPANY A SPECIAL
) to ensure that the additional, special policy group is applied for data access for Company A only. You would not apply this under the SUBSCRIBER
policy, because the policy relates only to Company A, and it is more efficient to segregate the basic hosting policy from other policies.
Within a group of security policies, you can designate one security policy to be the default security policy. This is useful in situations where you partition security policies by application, so that they will be always be in effect. Default security policies allow developers to base security enforcement under all conditions, while partitioning security policies by application (using security groups) enables layering of additional, application-specific security on top of default security policies. To implement default security policies, you add the policy to the SYS_DEFAULT
policy group.
Policies defined in this group for a particular table, view, or synonym are run with with the policy group specified by the driving context. As described earlier, a driving context is an application context that indicates the policy group in effect. The SYS_DEFAULT
policy group may or may not contain policies. You cannot to drop the SYS_DEFAULT
policy group. If you do, then Oracle Database displays an error.
If, to the SYS_DEFAULT
policy group, you add policies associated with two or more objects, then each object will have a separate SYS_DEFAULT
policy group associated with it. For example, the emp
table in the scott
schema has one SYS_DEFAULT
policy group, and the dept
table in the scott
schema has a different SYS_DEFAULT
policy group associated with it. Think of them as being organized in the tree structure as follows:
SYS_DEFAULT - policy1 (scott/emp) - policy3 (scott/emp) SYS_DEFAULT - policy2 (scott/dept)
You can create policy groups with identical names. When you select a particular policy group, its associated schema and object name are displayed in the property sheet on the right side of the screen.
You can establish several policies for the same table, view, or synonym. Suppose, for example, you have a base application for Order Entry, and each division of your company has its own rules for data access. You can add a division-specific policy function to a table without having to rewrite the policy function of the base application.
All policies applied to a table are enforced with AND
syntax. If you have three policies applied to the CUSTOMERS
table, then each policy is applied to the table. You can use policy groups and an application context to partition fine-grained access control enforcement so that different policies apply, depending upon which application is accessing data. This eliminates the requirement for development groups to collaborate on policies, and simplifies application development. You can also have a default policy group that is always applicable (for example, to enforce data separated by subscriber in a hosting environment).
The package implementing the driving context must correctly validate the application that is being used to connect to the database. Although Oracle Database checks the call stack to ensure that the package implementing the driving context sets context attributes, inadequate validation can still occur within the package.
For example, in applications where database users or enterprise users are known to the database, the user needs the EXECUTE
privilege on the package that sets the driving context. Consider a user who knows that:
The BENEFITS
application enables more liberal access than the HR
application.
The setctx
procedure (which sets the correct policy group within the driving context) does not perform any validation to determine which application is actually connecting. That is, the procedure does not check either the IP address of the incoming connection (for a three-tier system) or the proxy_user
attribute of the user session.
This user could pass to the driving context package an argument setting the context to the more liberal BENEFITS
policy group, and then access the HR
application instead. Because the setctx
does no further validation of the application, this user bypasses the more restrictive HR security policy.
By contrast, if you implement proxy authentication with Oracle Virtual Private Database, then you can determine the identity of the middle tier (and the application) that is connecting to the database on behalf of a user. The correct policy will be applied for each application to mediate data access.
For example, a developer using the proxy authentication feature could determine that the application (the middle tier) connecting to the database is HRAPPSERVER
. The package that implements the driving context can thus verify whether the proxy_user
in the user session is HRAPPSERVER
. If so, then it can set the driving context to use the HR
policy group. If proxy_user
is not HRAPPSERVER
, then it can deny access.
In this case, the following query is executed:
SELECT * FROM apps.benefit;
Oracle Database picks up policies from the default policy group (SYS_DEFAULT
) and active namespace HR
. The query is internally rewritten as follows:
SELECT * FROM apps.benefit WHERE company = SYS_CONTEXT('ID','MY_COMPANY') and SYS_CONTEXT('ID','TITLE') = 'MANAGER';
This section contains:
Using the Dynamic Policy Type to Automatically Rerun Policy Functions
Using a Static Policy to Prevent Policy Functions from Rerunning for Each Query
Using a Shared Static Policy to Share a Policy with Multiple Objects
Using a Context-Sensitive Policy for Predicates That Do Not Change After Parsing
Using a Shared Context Sensitive Policy to Share a Policy with Multiple Objects
When to Use Context-Sensitive and Shared Context-Sensitive Policies
Summary of the Five Oracle Virtual Private Database Policy Types
You can optimize performance each time a policy runs by specifying a policy type for your policies. Policy types control how Oracle Database caches Oracle Virtual Private Database policy predicates. Consider setting a policy type for your policies, because the execution of policy functions can use a significant amount of system resources. Minimizing the number of times that a policy function can run optimizes database performance.
You can choose from five policy types: DYNAMIC
, STATIC
, SHARED_STATIC
, CONTEXT_SENSITIVE
, and SHARED_CONTEXT_SENSITIVE
. These enable you to precisely specify how often a policy predicate should change. To specify the policy type, set the policy_type
parameter of the DBMS_RLS.ADD POLICY
procedure.
The DYNAMIC
policy type runs the policy function each time a user accesses the Virtual Private Database-protected database objects. If you do not specify a policy type in the DBMS_RLS.ADD_POLICY
procedure, then, by default, your policy will be dynamic. You can specifically configure a policy to be dynamic by setting the policy_type
parameter of the DBMS_RLS.ADD_POLICY
procedure to DYNAMIC
.
This policy type does not optimize database performance as the static and context sensitive policy types do. However, Oracle recommends that before you set policies as either static or context-sensitive, you should first test them as DYNAMIC
policy types, which run every time. Testing policy functions as DYNAMIC
policies first enables you to observe how the policy function affects each query, because nothing is cached. This ensures that the functions work properly before you enable them as static or context-sensitive policy types to optimize performance.
You can use the DBMS_UTILITY.GET_TIME
procedure to measure the start and end times for a statement to execute. For example:
-- 1. Get the start time: SELECT DBMS_UTILITY.GET_TIME FROM DUAL; GET_TIME ---------- 2312721 -- 2. Run the statement: SELECT COUNT(*) FROM HR.EMPLOYEES; COUNT(*) ---------- 107 -- 3. Get the end time: SELECT DBMS_UTILITY.GET_TIME FROM DUAL; GET_TIME ---------- 2314319
Example 7-5 shows how to create the DYNAMIC
policy type.
Example 7-5 Creating a DYNAMIC Policy with DBMS_RLS.ADD_POLICY
BEGIN DBMS_RLS.ADD_POLICY( object_schema => 'hr', object_name => 'employees', policy_name => 'secure_update', policy_function => 'hide_fin', policy_type => dbms_rls.DYNAMIC); END;
See Also:
"About Auditing Functions, Procedures, Packages, and Triggers" for information about how Oracle Database audits the underlying policy function for dynamic policiesThe static policy type enforces the same predicate for all users in the instance. Oracle Database stores static policy predicates in SGA, so policy functions do not rerun for each query. This results in faster performance.
You can enable static policies by setting the policy_type
parameter of the DBMS_RLS.ADD_POLICY
procedure to either STATIC
or SHARED_STATIC
, depending on whether or not you want the policy to be shared across multiple objects.
Example 7-6 shows how to create the STATIC
policy type.
Example 7-6 Creating a STATIC Policy with DBMS_RLS.ADD_POLICY
BEGIN DBMS_RLS.ADD_POLICY( object_schema => 'hr', object_name => 'employees', policy_name => 'secure_update', policy_function => 'hide_fin', policy_type => dbms_rls.STATIC); END;
Each execution of the same cursor could produce a different row set for the same predicate, because the predicate may filter the data differently based on attributes such as SYS_CONTEXT
or SYSDATE
.
For example, suppose you enable a policy as either a STATIC
or SHARED_STATIC
policy type, which appends the following predicate to all queries made against policy protected database objects:
WHERE dept = SYS_CONTEXT ('hr_app','deptno')
Although the predicate does not change for each query, it applies to the query based on session attributes of the SYS_CONTEXT
. In the case of the preceding example, the predicate returns only those rows where the department number matches the deptno
attribute of the SYS_CONTEXT
, which is the department number of the user who is querying the policy-protected database object.
Note:
When using shared static policies, ensure that the policy predicate does not contain attributes that are specific to a particular database object, such as a column name.See Also:
"About Auditing Functions, Procedures, Packages, and Triggers" for information about how Oracle Database audits the underlying policy function for static policiesIf, for example, you wanted to apply the policy in Example 7-6 to a second table in the HR
schema that may contain financial data that you want to side, you would use the SHARED_STATIC
setting for both tables.
Example 7-7 shows how to set the SHARED_STATIC
policy type for two tables that share the same policy.
Example 7-7 Creating a SHARED_STATIC Policy with DBMS_RLS.ADD_POLICY
-- 1. Create a policy for the first table, employees: BEGIN DBMS_RLS.ADD_POLICY( object_schema => 'hr', object_name => 'employees', policy_name => 'secure_update', policy_function => 'hide_fin', policy_type => dbms_rls.SHARED_STATIC); END; / -- 2. Create a policy for the second table, fin_data: BEGIN DBMS_RLS.ADD_POLICY( object_schema => 'hr', object_name => 'fin_data', policy_name => 'secure_update', policy_function => 'hide_fin', policy_type => dbms_rls.SHARED_STATIC); END; /
Static policies are ideal for environments where every query requires the same predicate and fast performance is essential, such as hosting environments. For these situations when the policy function appends the same predicate to every query, rerunning the policy function each time adds unnecessary overhead to the system. For example, consider a data warehouse that contains market research data for customer organizations that are competitors. The warehouse must enforce the policy that each organization can see only their own market research, which is expressed by the following predicate:
WHERE subscriber_id = SYS_CONTEXT('customer', 'cust_num')
Using SYS_CONTEXT
for the application context enables the database to dynamically change the rows that are returned. You do not need to rerun the function, so the predicate can be cached in the SGA, thus conserving system resources and improving performance.
In contrast to static policies, context-sensitive policies do not always cache the predicate. With context-sensitive policies, the database assumes that the predicate will change after statement parse time. But if there is no change in local application context, Oracle Database does not rerun the policy function within the user session. If there was a change in context, then the database reruns the policy function to ensure that it captures any changes to the predicate since the initial parsing.
You can enable context-sensitive policies by setting the policy_type
parameter of the DBMS_RLS.ADD_POLICY
procedure to either CONTEXT_SENSITIVE
or SHARED_CONTEXT_SENSITIVE
.
Example 7-8 shows how to create the CONTEXT_SENSITIVE
policy type.
Example 7-8 Creating a CONTEXT_SENSITIVE Policy with DBMS_RLS.ADD_POLICY
BEGIN DBMS_RLS.ADD_POLICY( object_schema => 'hr', object_name => 'employees', policy_name => 'secure_update', policy_function => 'hide_fin', policy_type => dbms_rls.CONTEXT_SENSITIVE); END; /
Context-sensitive policies are useful when different predicates should apply depending on which user is executing the query. For example, consider the case where managers should have the predicate WHERE group
set to managers
, and employees should have the predicate WHERE empno
set to emp_id
.
Shared context-sensitive policies operate in the same way as regular context-sensitive policies, except they can be shared across multiple database objects. For this policy type, all objects can share the policy function from the UGA, where the predicate is cached until the local session context changes.
Note:
When using shared context-sensitive policies, ensure that the policy predicate does not contain attributes that are specific to a particular database object, such as a column name.See Also:
"About Auditing Functions, Procedures, Packages, and Triggers" for information about how Oracle Database audits the underlying policy function for dynamic policiesExample 7-9 Ishows how to create two shared context sensitive policies that share a policy with multiple tables.
Example 7-9 Creating a SHARED_CONTEXT_SENSITIVE Policy with DBMS_RLS.ADD_POLICY
-- 1. Create a policy for the first table, employees: BEGIN DBMS_RLS.ADD_POLICY( object_schema => 'hr', object_name => 'employees', policy_name => 'secure_update', policy_function => 'hide_fin', policy_type => dbms_rls.SHARED_CONTEXT_SENSITIVE); END; / --2. Create a policy for the second table, fin_data: BEGIN DBMS_RLS.ADD_POLICY( object_schema => 'hr', object_name => 'fin_data', policy_name => 'secure_update', policy_function => 'hide_fin', policy_type => dbms_rls.SHARED_CONTEXT_SENSITIVE); END; /
Context-sensitive policies are useful when a predicate does not need to change for a user session, but the policy must enforce two or more different predicates for different users or groups. For example, consider a sales_history
table with a single policy. This policy states that analysts can see only their own products and regional employees can see only their own region. In this case, the database must rerun the policy function each time the type of user changes. The performance gain is realized when a user can log in and issue several DML statements against the protected object without causing the server to rerun the policy function.
Table 7-2 summarizes the types of policy types available.
Table 7-2 DBMS_RLS.ADD_POLICY Policy Types
Policy Types | When the Policy Function Executes | Usage Example | Shared Across Multiple Objects? |
---|---|---|---|
|
Policy function re-executes every time a policy-protected database object is accessed. |
Applications where policy predicates must be generated for each query, such as time-dependent policies where users are denied access to database objects at certain times during the day |
No |
|
Once, then the predicate is cached in the SGAFoot 1 |
View replacement |
No |
|
Same as |
Hosting environments, such as data warehouses where the same predicate must be applied to multiple database objects |
Yes |
|
|
Three-tier, session pooling applications where policies enforce two or more predicates for different users or groups |
No |
|
First time the object is reference in a database session. Predicates are cached in the private session memory UGA so policy functions can be shared among objects. |
Same as |
Yes |
Footnote 1 Each execution of the same cursor could produce a different row set for the same predicate because the predicate may filter the data differently based on attributes such as SYS_CONTEXT
or SYSDATE
.
This section contains:
Tutorial: Creating a Simple Oracle Virtual Private Database Policy
Tutorial: Implementing a Policy with a Database Session-Based Application Context
Tutorial: Implementing an Oracle Virtual Private Database Policy Group
Suppose you wanted to create a simple Oracle Virtual Private Database policy that limits access to all orders in the OE.ORDERS
table that were created by Sales Representative 159. In essence, the policy translates the following statement:
SELECT * FROM OE.ORDERS;
To the following statement:
SELECT * FROM OE.ORDERS WHERE SALES_REP_ID = 159;
In this tutorial:
Log on to SQL*Plus as user SYS
with the SYSDBA
privilege.
sqlplus sys as sysdba
Enter password: password
Run the following SELECT
statement on the DBA_USERS
data dictionary view:
SELECT USERNAME, ACCOUNT_STATUS FROM DBA_USERS WHERE USERNAME = 'OE';
If the DBA_USERS
view lists user OE
as locked and expired, then enter the following statement to unlock the OE
account and create a new password:
ALTER USER OE ACCOUNT UNLOCK IDENTIFIED BY password;
Replace password
with a password that is secure. For greater security, do not reuse the same password that was used in previous releases of Oracle Database. See "Minimum Requirements for Passwords" for more information.
Create the following function, which will append the WHERE SALES_REP_ID = 159
clause to any SELECT
statement on the OE.ORDERS
table.
1 2 3 4 5 6 7 8 9 10 11 12 |
CREATE OR REPLACE FUNCTION auth_orders( schema_var IN VARCHAR2, table_var IN VARCHAR2 ) RETURN VARCHAR2 IS return_val VARCHAR2 (400); BEGIN return_val := 'SALES_REP_ID = 159'; RETURN return_val; END auth_orders; / |
In this example:
Lines 2–3: Create input parameters to specify to store the schema name, OE
, and table name, ORDERS
. First, define the parameter for the schema, and then define the parameter for the object, in this case, a table. Always create them in this order. The Virtual Private Database policy you create will need these parameters to specify the OE.ORDERS
table.
Line 5: Returns the string that will be used for the WHERE
predicate clause. Remember that return value is always a VARCHAR2
data type.
Lines 6–10: Encompass the creation of the WHERE SALES_REP_ID = 159
predicate.
Next, create the following policy by using the ADD_POLICY
procedure in the DBMS_RLS
package.
1 2 3 4 5 6 7 8 9 10 11 |
BEGIN DBMS_RLS.ADD_POLICY ( object_schema => 'oe', object_name => 'orders', policy_name => 'orders_policy', function_schema => 'sys', policy_function => 'auth_orders', statement_types => 'select, insert, update, delete' ); END; / |
In this example:
Line 3: Specifies the schema that you want to protect, that is, OE
.
Line 4: Specifies the object within the schema to protect, that is, the ORDERS
table.
Line 5: Names this policy orders_policy
.
Line 6: Specifies the schema in which the auth_orders
function was created. In this example, auth_orders
was created in the SYS
schema. But typically, it should be created in the schema of a security administrator.
Line 7: Specifies a function to enforce the policy. Here, you specify the auth_orders
function that you created in Step 2: Create a Policy Function.
Line 8: Specifies the operations to which the policy applies. In this example, the policy applies to all SELECT
, INSERT
, UPDATE
, and DELETE
statements the user may perform.
After you create the Oracle Virtual Private Database policy, it goes into effect immediately. The next time a user, including the owner of the schema, performs a SELECT
on OE.ORDERS
, only the orders by Sales Representative 159 will be accessed.
Log on as user OE
.
CONNECT oe
Enter password: password
Enter the following SELECT
statement:
SELECT COUNT(*) FROM ORDERS;
The following output should appear:
COUNT(*) --------- 7
The policy is in effect for user OE
: As you can see, only 7 of the 105 rows in the orders table are returned.
But users with administrative privileges still have access to all the rows in the table.
Log back on as user SYS
.
CONNECT sys/as sysdba
Enter password: password
Enter the following SELECT
statement:
SELECT COUNT(*) FROM OE.ORDERS;
The following output should appear:
COUNT(*) --------- 105
As user SYS
, remove the function and policy as follows:
DROP FUNCTION auth_orders; EXEC DBMS_RLS.DROP_POLICY('OE','ORDERS','ORDERS_POLICY');
If you need to lock and expire the OE
account, then enter the following statement:
ALTER USER OE ACCOUNT LOCK PASSWORD EXPIRE;
This tutorial shows how you can use a database session-based application context to implement a policy in which customers can see only their own orders. You create the following layers of security:
When a user logs on, a database session-based application context checks whether the user is a customer. If a user is not a customer, the user still can log on, but this user cannot access the orders entry table you will create for this example.
If the user is a customer, he or she can log on. After the customer has logged on, an Oracle Virtual Private Database policy restricts this user to see only his or her orders.
As a further restriction, Oracle Virtual Private Database policy permits the user to only view his or her orders. The user cannot add, modify, or remove orders.
In this tutorial:
Step 3: Create a PL/SQL Package to Set the Application Context
Step 4: Create a Logon Trigger to Run the Application Context PL/SQL Package
Step 5: Create a PL/SQL Policy Function to Limit User Access to Their Orders
Start SQL*Plus and log on as a user who has administrative privileges.
sqlplus sys as sysdba
Enter password: password
Create the following administrative user, who will administer the Oracle Virtual Private Database policy.
The following SQL statements create this user and then grant the user the necessary privileges for completing this tutorial.
GRANT CREATE SESSION, CREATE ANY CONTEXT, CREATE PROCEDURE, CREATE TRIGGER, ADMINISTER DATABASE TRIGGER TO sysadmin_vpd IDENTIFIED BY password;
GRANT EXECUTE ON DBMS_SESSION TO sysadmin_vpd;
GRANT EXECUTE ON DBMS_RLS TO sysadmin_vpd;
Replace password
with a password that is secure. See "Minimum Requirements for Passwords" for more information.
Create the following user accounts:
GRANT CREATE SESSION TO tbrooke IDENTIFIED BY password; GRANT CREATE SESSION TO owoods IDENTIFIED BY password;
Replace password
with a password that is secure. See "Minimum Requirements for Passwords" for more information.
Check the status of the sample user SCOTT
, who you will use for this tutorial:
SELECT USERNAME, ACCOUNT_STATUS FROM DBA_USERS WHERE USERNAME = 'SCOTT';
If the DBA_USERS
view lists user SCOTT
as locked and expired, then enter the following statement to unlock the SCOTT
account and create a new password for him:
ALTER USER SCOTT ACCOUNT UNLOCK IDENTIFIED BY password;
Replace password
with a password that is secure. For greater security, do not reuse the same password that was used in previous releases of Oracle Database. See "Minimum Requirements for Passwords" for more information.
Connect as user SCOTT
, and then create and populate the customers
table.
CONNECT scott
Enter password: password
CREATE TABLE customers (
cust_no NUMBER(4),
cust_email VARCHAR2(20),
cust_name VARCHAR2(20));
INSERT INTO customers VALUES (1234, 'TBROOKE', 'Thadeus Brooke');
INSERT INTO customers VALUES (5678, 'OWOODS', 'Oberon Woods');
When you enter the user e-mail addresses, enter them in upper-case letters. Later on, when you create the application context PL/SQL package, the SESSION_USER
parameter of the SYS_CONTEXT
function expects the user names to be in upper case. Otherwise, you will be unable to set the application context for the user.
User sysadmin_vpd
will need SELECT
privileges for the customers table, so as user SCOTT
, grant him this privilege.
GRANT SELECT ON customers TO sysadmin_vpd;
Create and populate the orders_tab
table.
CREATE TABLE orders_tab ( cust_no NUMBER(4), order_no NUMBER(4)); INSERT INTO orders_tab VALUES (1234, 9876); INSERT INTO orders_tab VALUES (5678, 5432); INSERT INTO orders_tab VALUES (5678, 4592);
Users tbrooke
and owoods
need to query the orders_tab
table, so grant them the SELECT
privilege.
GRANT SELECT ON orders_tab TO tbrooke; GRANT SELECT ON orders_tab TO owoods;
At this stage, the two sample customers, tbrooke
and owoods
, have a record of purchases in the orders_tab
order entry table, and if they tried right now, they can see all the orders in this table.
Connect as user sysadmin_vpd
.
CONNECT sysadmin_vpd
Enter password: password
Enter the following statement:
CREATE OR REPLACE CONTEXT orders_ctx USING orders_ctx_pkg;
This statement creates the orders_ctx
application context. Remember that even though user sysadmin_vpd
has created this context and it is associated with the sysadmin_vpd
schema, the SYS
schema owns the application context.
As user sysadmin_vpd
, create the following PL/SQL package, which will set the database session-based application context when the customers tbrooke
and owoods
log onto their accounts.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 |
CREATE OR REPLACE PACKAGE orders_ctx_pkg IS PROCEDURE set_custnum; END; / CREATE OR REPLACE PACKAGE BODY orders_ctx_pkg IS PROCEDURE set_custnum AS custnum NUMBER; BEGIN SELECT cust_no INTO custnum FROM scott.customers WHERE cust_email = SYS_CONTEXT('USERENV', 'SESSION_USER'); DBMS_SESSION.SET_CONTEXT('orders_ctx', 'cust_no', custnum); EXCEPTION WHEN NO_DATA_FOUND THEN NULL; END set_custnum; END; / |
In this example:
Line 8: Creates the custnum
variable, which will hold the customer ID.
Line 10: Performs a SELECT
statement to copy the customer ID that is stored in the cust_no
column data from the scott.customers
table into the custnum
variable.
Line 11: Uses a WHERE
clause to find all the customer IDs that match the user name of the user who is logging on.
Line 12: Sets the order_entry
application context values by creating the cust_no
attribute and then setting it to the value stored in the custnum
variable.
Lines 13–14: Add a WHEN NO_DATA_FOUND
system exception to catch any no data found
errors that may result from the SELECT
statement in Lines 10–11.
To summarize, the sysadmin_vpd.set_cust_num
procedure identifies whether or not the session user is a registered customer by attempting to select the user's customer ID into the custnum
variable. If the user is a registered customer, then Oracle Database sets an application context value for this user. As you will see in Step 5: Create a PL/SQL Policy Function to Limit User Access to Their Orders, the policy function uses the context value to control the access a user has to data in the orders_tab
table.
The logon trigger runs the procedure in the PL/SQL package that you created in Step 3: Create a PL/SQL Package to Set the Application Context the next time a user logs on, so that the application context can be set.
As user sysadmin_vpd
, create the following trigger:
CREATE TRIGGER set_custno_ctx_trig AFTER LOGON ON DATABASE BEGIN sysadmin_vpd.orders_ctx_pkg.set_custnum; END; /
At this stage, if you log on as either tbrooke
or owoods
, the logon trigger should set the application context for the user when it fires the sysadmin_vpd.orders_ctx_pkg.set_custnum
procedure. You can test it as follows:
CONNECT tbrooke
Enter password: password
SELECT SYS_CONTEXT('orders_ctx', 'cust_no') custnum FROM DUAL;
The following output should appear:
EMP_ID ------------------------------------------------------------------- 1234
The next step is to create a PL/SQL function that, when the user who has logged in performs a SELECT * FROM scott.orders_tab
query, displays only the orders of that user.
As user sysadmin_vpd
, create the following function:
CREATE OR REPLACE FUNCTION get_user_orders( schema_p IN VARCHAR2, table_p IN VARCHAR2) RETURN VARCHAR2 AS orders_pred VARCHAR2 (400); BEGIN orders_pred := 'cust_no = SYS_CONTEXT(''orders_ctx'', ''cust_no'')'; RETURN orders_pred; END; /
This function creates and returns a WHERE
predicate that translates to "WHERE
the orders displayed belong to the user who has logged in." It then appends this WHERE
predicate to any queries this user may run against the scott.orders_tab
table. Next, you need to create an Oracle Virtual Private Database policy that applies this function to the orders_tab
table.
As user sysadmin_vpd
, create the policy as follows:
BEGIN DBMS_RLS.ADD_POLICY ( object_schema => 'scott', object_name => 'orders_tab', policy_name => 'orders_policy', function_schema => 'sysadmin_vpd', policy_function => 'get_user_orders', statement_types => 'select'); END; /
This statement creates a policy named orders_policy
and applies it to the orders_tab
table, which customers will query for their orders, in the SCOTT
schema. The get_user_orders
function implements the policy, which is stored in the sysadmin_vpd
schema. The policy further restricts users to issuing SELECT
statements only.
Log on as user tbrooke
.
CONNECT tbrooke
Enter password: password
User tbrooke
can log on because he has passed the requirements you defined in the application context.
As user tbrooke
, access your purchases.
SELECT * FROM scott.orders_tab;
The following output should appear:
CUST_NO ORDER_NO ---------- ---------- 1234 9876
User tbrooke
has passed the second test. He can access his own orders in the scott.orders_tab
table.
Log on as user owoods
, and then access your purchases.
CONNECT owoods
Enter password: passwords
SELECT * FROM scott.orders_tab
The following output should appear:
CUST_NO ORDER_NO ---------- ---------- 5678 5432 5678 4592
As with user tbrooke
, user owoods
can log on and see a listing of his own orders.
Note the following:
You can create several predicates based on the position of a user. For example, a sales representative would be able to see records only for his customers, and an order entry clerk would be able to see any customer order. You could expand the custnum_sec
function to return different predicates based on the user position context value.
The use of an application context in a fine-grained access control package effectively gives you a bind variable in a parsed statement. For example:
SELECT * FROM scott.orders_tab WHERE cust_no = SYS_CONTEXT('order_entry', 'cust_num');
This is fully parsed and optimized, but the evaluation of the cust_num
attribute value of the user for the order_entry
context takes place at run-time. This means that you get the benefit of an optimized statement that executes differently for each user who issues the statement.
You can set context attributes based on data from a database table or tables, or from a directory server using Lightweight Directory Access Protocol (LDAP).
See Also:
Oracle Database PL/SQL Language Reference for more information about triggersCompare and contrast this tutorial, which uses an application context within the dynamically generated predicate, with "About Oracle Virtual Private Database Policies", which uses a subquery in the predicate.
Connect as user OE
and remove the orders_tab
and customers
tables.
CONNNECT SCOTT
Enter password: password
DROP TABLE orders_tab;
DROP TABLE customers;
Connect as user SYS
, connecting with AS SYSDBA
.
CONNECT sys/as sysdba
Enter password: password
Run the following statements to drop the components for this tutorial:
DROP CONTEXT orders_ctx; DROP USER sysadmin_vpd CASCADE; DROP USER tbrooke; DROP USER owoods;
"Working with Oracle Virtual Private Database Policy Groups" describes how you can group a set of policies for use in an application. When a nondatabase user logs onto the application, Oracle Database grants the user access based on the policies defined within the appropriate policy group.
For column-level access control, every column or set of hidden columns is controlled by one policy. In this tutorial, you must hide two sets of columns. So, you need to create two policies, one for each set of columns that you want to hide. You only want one policy for each user; the driving application context separates the policies for you.
In this tutorial:
Step 1: Create User Accounts and Other Components for This Tutorial
Step 3: Create PL/SQL Functions to Control the Policy Groups
Log on as user SYS
with the SYSDBA
privilege.
sqlplus sys as sysdba
Enter password: password
Create the following users:
GRANT CREATE SESSION TO apps_user IDENTIFIED BY password; GRANT CREATE SESSION, CREATE PROCEDURE, CREATE ANY CONTEXT TO sysadmin_pg IDENTIFIED BY password;
Replace password
with a password that is secure. See "Minimum Requirements for Passwords" for more information.
Grant the following additional privilege to user sysadmin_pg
:
GRANT EXECUTE ON DBMS_RLS TO sysadmin_pg;
Log on as user OE
.
CONNECT OE
Enter password: password
If the OE
account is locked and expired, then reconnect as user SYS
with the SYSDBA
privilege and enter the following statement to unlock the account and give it s new password:
ALTER USER OE ACCOUNT UNLOCK IDENTIFIED BY password;
Replace password
with a password that is secure. For greater security, do not reuse the same password that was used in previous releases of Oracle Database. See "Minimum Requirements for Passwords" for more information.
Create the product_code_names
table:
CREATE TABLE product_code_names( group_a varchar2(32), year_a varchar2(32), group_b varchar2(32), year_b varchar2(32));
Insert some values into the product_code_names
table:
INSERT INTO product_code_names values('Harpo','2008','Groucho','2004'); INSERT INTO product_code_names values('Margaret Dumont','2008','Zeppo','2008'); INSERT INTO product_code_names values('Chico','2006','Margaret Dumont','2003'); COMMIT;
Grant the apps_user
user SELECT
privileges on the product_code_names
table.
GRANT SELECT ON product_code_names TO apps_user;
Next, you must create a policy group for each of the two nondatabase users, provider_a
and provider_b
.
Connect as user sysadmin_pg
.
CONNECT sysadmin_pg
Enter password: password
Create the provider_a_group
policy group, to be used by user provider_a
:
BEGIN DBMS_RLS.CREATE_POLICY_GROUP( OBJECT_SCHEMA => 'oe', OBJECT_NAME => 'product_code_names', POLICY_GROUP => 'provider_a_group'); END; /
Create the provider_b_group
policy group, to be used by user provider_b
:
BEGIN DBMS_RLS.CREATE_POLICY_GROUP( OBJECT_SCHEMA => 'oe', OBJECT_NAME => 'product_code_names', POLICY_GROUP => 'provider_b_group'); END; /
Each of the policy groups that you created in Step 2: Create the Two Policy Groups must have a function that defines how the application can control data access for users provider_a
and provider_b
.
Create the vpd_function_provider_a
function, which restricts the data accessed by user provider_a
.
CREATE OR REPLACE FUNCTION vpd_function_provider_a (schema in varchar2, tab in varchar2) return varchar2 as predicate varchar2(8) default NULL; BEGIN IF LOWER(SYS_CONTEXT('USERENV','CLIENT_IDENTIFIER')) = 'provider_a' THEN predicate := '1=2'; ELSE NULL; END IF; RETURN predicate; END; /
This function checks that the user logging in is really user provider_a
. If this is true, then only the data in the product_code_names
table columns group_a
and year_a
will be visible to provider_a
. Data in columns group_b
and year_b
will not appear for provider_a
. This works as follows: Setting predicate := '1=2'
hides the relevant columns. In Step 4: Add the PL/SQL Functions to the Policy Groups, you specify these columns in the SEC_RELEVANT_COLS
parameter.
See "Creating a Function to Generate the Dynamic WHERE Clause" for detailed information on the components of this type of function.
Create the vpd_function_provider_b
, function, which restricts the data accessed by user provider_a
.
CREATE OR REPLACE FUNCTION vpd_function_provider_b (schema in varchar2, tab in varchar2) return varchar2 as predicate varchar2(8) default NULL; BEGIN IF LOWER(SYS_CONTEXT('USERENV','CLIENT_IDENTIFIER')) = 'provider_b' THEN predicate := '1=2'; ELSE NULL; END IF; RETURN predicate; END; /
Similar to the vpd_function_provider_a
function, this function checks that the user logging in is really user provider_b
. If this is true, then only the data in the columns group_b
and year_b
will be visible to provider_b
, with data in the group_a
and year_a
not appearing for provider_b
. Similar to the vpd_function_provider_a
function, predicate := '1=2'
hides the relevant columns specified Step 4: Add the PL/SQL Functions to the Policy Groups in the SEC_RELEVANT_COLS
parameter.
Now that you have created the necessary functions, you are ready to associate them with their appropriate policy groups.
Add the vpd_function_provider_a
function to the provider_a_group
policy group.
BEGIN DBMS_RLS.ADD_GROUPED_POLICY( OBJECT_SCHEMA => 'oe', OBJECT_NAME => 'product_code_names', POLICY_GROUP => 'provider_a_group', POLICY_NAME => 'filter_provider_a', FUNCTION_SCHEMA => 'sysadmin_pg', POLICY_FUNCTION => 'vpd_function_provider_a', STATEMENT_TYPES => 'select', POLICY_TYPE => DBMS_RLS.CONTEXT_SENSITIVE, SEC_RELEVANT_COLS => 'group_b,year_b', SEC_RELEVANT_COLS_OPT => DBMS_RLS.ALL_ROWS); END; /
The group_b
and year_b
columns specified in the SEC_RELEVANT_COLS
parameter are hidden from user provider_a
.
Add the vpd_function_provider_b
function to the provider_b_group
policy group.
BEGIN DBMS_RLS.ADD_GROUPED_POLICY( OBJECT_SCHEMA => 'oe', OBJECT_NAME => 'product_code_names', POLICY_GROUP => 'provider_b_group', POLICY_NAME => 'filter_provider_b', FUNCTION_SCHEMA => 'sysadmin_pg', POLICY_FUNCTION => 'vpd_function_provider_b', STATEMENT_TYPES => 'select', POLICY_TYPE => DBMS_RLS.CONTEXT_SENSITIVE, SEC_RELEVANT_COLS => 'group_a,year_a', SEC_RELEVANT_COLS_OPT => DBMS_RLS.ALL_ROWS); END; /
The group_a
and year_a
columns specified in the SEC_RELEVANT_COLS
parameter are hidden from user provider_b
.
The application context determines which policy the nondatabase user who is the logging on should use.
As user sysadmin_pg
, create the driving application context as follows:
CREATE OR REPLACE CONTEXT provider_ctx USING provider_package;
Create the PL/SQL provider_package
package for the application context.
CREATE OR REPLACE PACKAGE provider_package IS PROCEDURE set_provider_context (policy_group varchar2 default NULL); END; / CREATE OR REPLACE PACKAGE BODY provider_package AS PROCEDURE set_provider_context (policy_group varchar2 default NULL) IS BEGIN CASE LOWER(SYS_CONTEXT('USERENV', 'CLIENT_IDENTIFIER')) WHEN 'provider_a' THEN DBMS_SESSION.SET_CONTEXT('provider_ctx','policy_group','PROVIDER_A_GROUP'); WHEN 'provider_b' THEN DBMS_SESSION.SET_CONTEXT('provider_ctx','policy_group','PROVIDER_B_GROUP'); END CASE; END set_provider_context; END; /
Associate the provider_ctx
application context with the product_code_names
table, and then provide a name.
BEGIN DBMS_RLS.ADD_POLICY_CONTEXT( object_schema =>'oe', object_name =>'product_code_names', namespace =>'provider_ctx', attribute =>'policy_group'); END; /
Grant the apps_user
account the EXECUTE
privilege for the provider_package
package.
GRANT EXECUTE ON provider_package TO apps_user;
Now you are ready to test the two policy groups.
Connect as user apps_user
and then enter the following statements to ensure that the output you will create later on is nicely formatted.
CONNECT apps_user
Enter password: password
col group_a format a16
col group_b format a16;
col year_a format a16;
col year_b format a16;
Set the session identifier to provider_a
.
EXEC DBMS_SESSION.SET_IDENTIFIER('provider_a');
Here, the application sets the identifier. Setting the identifier to provider_a
sets the apps_user
user to a user who should only see the products available to products in the provider_a_group
policy group.
Run the provider_package
to set the policy group based on the context.
EXEC sysadmin_pg.provider_package.set_provider_context;
At this stage, you can check the application context was set, as follows:
SELECT SYS_CONTEXT('USERENV', 'CLIENT_IDENTIFIER') AS END_USER FROM DUAL;
The following output should appear:
END_USER ----------------- provider_a
Enter the following SELECT
statement:
SELECT * FROM oe.product_code_names;
The following output should appear:
GROUP_A YEAR_A GROUP_B YEAR_B ---------------- ---------------- ---------------- ---------------- Harpo 2008 Margaret Dumont 2008 Chico 2006
Set the client identifier to provider_b
and then enter the following statements:
EXEC DBMS_SESSION.SET_IDENTIFIER('provider_b'); EXEC sysadmin_pg.provider_package.set_provider_context; SELECT * FROM oe.product_code_names;
The following output should appear:
GROUP_A YEAR_A GROUP_B YEAR_B ---------------- ---------------- ---------------- ---------------- Groucho 2004 Zeppo 2008 Margaret Dumont 2003
Connect as user OE
and drop the product_code_names
table.
CONNECT OE
Enter password: password
DROP TABLE product_code_names;
Connect as user SYS
and drop the application context and users for this tutorial.
CONNECT SYS/AS SYSDBA
Enter password: password
DROP CONTEXT provider_ctx;
DROP USER sysadmin_pg cascade;
DROP USER apps_user;
This section contains:
Using Oracle Virtual Private Database Policies with Editions
Using SELECT FOR UPDATE in User Queries on VPD-Protected Tables
How Oracle Virtual Private Database Policies Affect Outer or ANSI Join Operations
How Oracle Virtual Private Database Security Policies Work with Applications
Using Automatic Reparsing for Fine-Grained Access Control Policy Functions
Using Oracle Virtual Private Database Policies and Flashback Query
Using Oracle Virtual Private Database and Oracle Label Security
If you are preparing an application for edition-based redefinition, and you cover each table that the application uses with an editioning view, then you must move the Virtual Private Database polices that protect these tables to the editioning view.
When an editioned object has a Virtual Private Database t policy, then it applies in all editions in which the object is visible. When an editioned object is actualized, any VPD policies that are attached to it are newly attached to the new actual occurrence. When you newly apply a VPD policy to an inherited editioned object, this action will actualize it.
See Also:
Oracle Database Advanced Application Developer's Guide for detailed information about editionsAs a general rule, users should not include the FOR UPDATE
clause when querying Virtual Private Database-protected tables. The Virtual Private Database technology depends on rewriting the user's query against an inline view that includes the VPD predicate generated by the VPD policy function. Because of this, the same limitations on views also apply to VPD-protected tables. If a user's query against a VPD-protected table includes the FOR UPDATE
clause in a SELECT
statement, in most cases, the query may not work. However, the user's query may work in some situations if the inline view generated by VPD is sufficiently simple.
See Also:
Oracle Database SQL Language Reference for more information about the restrictions of theFOR UPDATE
clause in the SELECT
statementOracle Virtual Private Database rewrites SQL by using dynamic views. For SQL that contains outer join or ANSI operations, some views may not merge and some indexes may not be used. This problem is a known optimization limitation. To remedy this problem, rewrite the SQL to not use outer joins or ANSI operations.
An Oracle Virtual Private Database security policy is applied within the database itself, rather than within an application. Hence, a user trying to access data by using a different application cannot bypass the Oracle Virtual Private Database security policy. Another advantage of creating the security policy in the database is that you maintain it in one central place, rather than maintaining individual security policies in multiple applications. Oracle Virtual Private Database provides stronger security than application-based security, at a lower cost of ownership.
You may want to enforce different security policies depending on the application that is accessing data. Consider a situation in which two applications, Order Entry and Inventory, both access the orders
table. You may want to have the Inventory application use a policy that limits access based on type of product. At the same time, you may want to have the Order Entry application use a policy that limits access based on customer number.
In this case, you must partition the use of fine-grained access by application. Otherwise, both policies would be automatically concatenated together, which may not be the result that you want. You can specify two or more policy groups, and a driving application context that determines which policy group is in effect for a given transaction. You can also designate default policies that always apply to data access. In a hosted application, for example, data access should be limited by subscriber ID. See "Tutorial: Implementing an Oracle Virtual Private Database Policy Group" for an example of how you can create policy groups that use an application context to determine which group should be used.
By default, queries against objects enabled with fine-grained access control run the policy function to ensure that the most current predicate is used for each policy. For example, in the case of a time-based policy function, in which queries are only allowed between 8:00 a.m. and 5:00 p.m., a cursor execution parsed at noon runs the policy function at that time, ensuring that the policy is consulted again for the query. Even if the curser was parsed at 9 a.m., when it runs later on (for example, at noon), then the Virtual Private Database policy function runs again to ensure that the execution of the cursor is still permitted at the current time (noon). This ensures that the security check it must perform is the most recent.
Automatic re-execution of the Virtual Private Database policy function does not occur when you set the DBMS_RLS.ADD_POLICY
setting STATIC_POLICY
to TRUE
while adding the policy. This setting causes the policy function to return the same predicate.
By default, operations on the database use the most recently committed data available. The flashback query feature enables you to query the database at some point in the past. To write an application that uses flashback query, you can use the AS OF
clause in SQL queries to specify either a time or a system change number (SCN), and then query against the committed data from the specified time. You can also use the DBMS_FLASHBACK
PL/SQL package, which requires more code, but enables you to perform multiple operations, all of which refer to the same point in time.
However, if you use flashback query against a database object that is protected with Oracle Virtual Private Database policies, then the current policies are applied to the old data. Applying the current Oracle Virtual Private Database policies to flashback query data is more secure because it reflects the most current business policy.
See Also:
Oracle Database Advanced Application Developer's Guide for more information about the flashback query feature and how to write applications that use it
Oracle Database PL/SQL Packages and Types Reference for more information about the DBMS_FLASHBACK
PL/SQL package
This section contains:
Using Oracle Virtual Private Database to Enforce Oracle Label Security Policies
Oracle Virtual Private Database and Oracle Label Security Exceptions
You can use Oracle Virtual Private Database policies to provide column or row-level access control based on Oracle Label Security user authorizations. In general, you need to perform the following steps:
When you create the Oracle Label Security policy, do not apply the policy to the table that you want to protect. (The Virtual Private Database policy that you create handles this for you.) In the SA_SYSDBA.CREATE_POLICY
procedure, set the default_options
parameter to NO_CONTROL
.
Create the Oracle Label Security label components and authorize users as you normally would.
When you create the Oracle Virtual Private Database policy, do the following:
In the PL/SQL function you create for the policy, use the Oracle Label Security DOMINATES
function to compare the authorization of the user with the label that you created in Step 2. (See Oracle Label Security Administrator's Guide for more information about the dominance functions.) The DOMINATES
function determines if the user authorization is equal to, or if it is more sensitive than, the label used in the comparison. If the user authorization passes, then the user is granted access to the column. Otherwise, the user is denied access.
In the Virtual Private Database policy definition, apply this function to the table that you want to protect. In the DBMS_RLS.ADD_POLICY
procedure, use the sensitive column (sec_relevant_cols
parameter) and column masking (sec_relevant_cols_opt
parameter) functionality to show or hide columns based on Oracle Label Security user authorizations.
For an example of how to accomplish this, visit the following Oracle Technology Network site:
http://www.oracle.com/technology/deploy/security/database-security/label-security/ols_cs1.html
Be aware of the following exceptions when you use Oracle Virtual Private Database and Oracle Label Security:
When you are exporting data, Oracle Virtual Private Database and Oracle Label Security policies are not enforced during a direct path export operation. In a direct path export operation, Oracle Database reads data from disk into the buffer cache and transfers rows directly to the Export client. See Oracle Database Utilities for more information about direct path export operations.
You cannot apply Oracle Virtual Private Database policies and Oracle Label Security policies to objects in the SYS schema. The SYS
user and users making a DBA-privileged connection to the database (for example, CONNECT/AS SYSDBA
) do not have Oracle Virtual Private Database or Oracle Label Security policies applied to their actions. The database user SYS
is thus always exempt from Oracle Virtual Private Database or Oracle Label Security enforcement, regardless of the export mode, application, or utility used to extract data from the database.
However, you can audit SYSDBA
actions by enabling auditing upon installation and specifying that this audit trail be stored in a secure location in the operating system. See "Auditing SYS Administrative Users" for more information. You can also closely monitor the SYS
user by using Oracle Database Vault.
Database users who were granted the EXEMPT ACCESS POLICY privilege, either directly or through a database role, are exempt from Oracle Virtual Private Database enforcements. The system privilege EXEMPT ACCESS POLICY
allows a user to be exempted from all fine-grained access control policies on any SELECT
or DML operation (INSERT
, UPDATE
, and DELETE
). This provides ease of use for administrative activities, such as installation and import and export of the database, through a non-SYS
schema.
However, the following policy enforcement options remain in effect even when EXEMPT ACCESS POLICY
is granted:
INSERT_CONTROL
, UPDATE_CONTROL
, DELETE_CONTROL
, WRITE_CONTROL
, LABEL_UPDATE
, and LABEL_DEFAULT
If the Oracle Label Security policy specifies the ALL_CONTROL
option, then all enforcement controls are applied except READ_CONTROL
and CHECK_CONTROL
.
Because EXEMPT ACCESS POLICY
negates the effect of fine-grained access control, you should only grant this privilege to users who have legitimate reasons for bypassing fine-grained access control enforcement. Do not grant this privilege using the WITH ADMIN OPTION
. If you do, users could pass the EXEMPT ACCESS POLICY
privilege to other users, and thus propagate the ability to bypass fine-grained access control.
Note:
The EXEMPT ACCESS POLICY
privilege does not affect the enforcement of object privileges such as SELECT
, INSERT
, UPDATE
, and DELETE
. These privileges are enforced even if a user was granted the EXEMPT ACCESS POLICY
privilege.
The SYS_CONTEXT
values that Oracle Virtual Private Database uses are not propagated to secondary databases for failover.
You can use Oracle Virtual Private Database in the following types of user models:
Application users who are also database users. Oracle Database enables applications to enforce fine-grained access control for each user, regardless of whether that user is a database user or an application user unknown to the database. When application users are also database users, Oracle Virtual Private Database enforcement works as follows: users connect to the database, and then the application sets up application contexts for each session. (You can use the default USERENV
application context namespace, which provides many parameters for retrieve different types of user session data.) As each session is initiated under a different user name, it can enforce different fine-grained access control conditions for each user.
Proxy authentication using OCI or JDBC/OCI. Proxy authentication permits different fine-grained access control for each user, because each session (OCI or JDBC/OCI) is a distinct database session with its own application context.
Proxy authentication integrated with Enterprise User Security. If you have integrated proxy authentication by using Enterprise User Security, you can retrieve user roles and other attributes from Oracle Internet Directory to enforce Oracle Virtual Private Database policies. (In addition, globally initialized application context can also be retrieved from the directory.)
Users connecting as One Big Application User. Applications connecting to the database as a single user on behalf of all users can have fine-grained access control for each user. The user for that single session is often called One Big Application User. Within the context of that session, however, an application developer can create a global application context attribute to represent the individual application user (for example, REALUSER
). Although all database sessions and audit records are created for One Big Application User, the attributes for each session can vary, depending on who the end user is. This model works best for applications with a limited number of users and no reuse of sessions. The scope of roles and database auditing is diminished because each session is created as the same database user. For more information about global application contexts, see "Using Global Application Contexts".
Web-based applications. Web-based applications typically have hundreds of users. Even when there are persistent connections to the database, supporting data retrieval for many user requests, these connections are not specific to particular Web-based users. Instead, Web-based applications typically set up and reuse connections, to provide scalability, rather than having different sessions for each user. For example, when Web users Jane and Ajit connect to a middle tier application, it may establish a single database session that it uses on behalf of both users. Typically, neither Jane nor Ajit is known to the database. The application is responsible for switching the user name on the connection, so that, at any given time, it is either Jane or Ajit using the session.
Oracle Virtual Private Database helps with connection pooling by allowing multiple connections to access more than one global application context. This ability makes it unnecessary to establish a separate application context for each distinct user session.
Table 7-3 summarizes how Oracle Virtual Private Database applies to user models.
Table 7-3 Oracle Virtual Private Database in Different User Models
User Model Scenario | Individual Database Connection | Separate Application Context per User | Single Database Connection | Application Must Switch User Name |
---|---|---|---|---|
Application users are also database users |
Yes |
Yes |
No |
No |
Proxy authentication using OCI or JDBC/OCI |
Yes |
Yes |
No |
No |
Proxy authentication integrated with Enterprise User SecurityFoot 1 |
No |
No |
Yes |
Yes |
One Big Application User |
No |
NoFoot 2 |
No |
Yes2 |
Web-based applications |
No |
No |
Yes |
Yes |
Footnote 1 User roles and other attributes, including globally initialized application context, can be retrieved from Oracle Internet Directory to enforce Oracle Virtual Private Database.
Footnote 2 Application developers can create a global application context attribute representing individual application users (for example, REALUSER)
, which can then be used for controlling each session attributes, or for auditing.
Table 7-4 lists data dictionary views that you can use to find information about Oracle Virtual Private Database policies. See Oracle Database Reference for more information about these views.
Table 7-4 Data Dictionary Views That Display Information about Oracle Virtual Private Database Policies
View | Description |
---|---|
|
Describes all Oracle Virtual Private Database security policies for objects accessible to the current user. |
|
Describes the driving contexts defined for the synonyms, tables, and views accessible to the current user. A driving context is an application context used in an Oracle Virtual Private Database policy. |
|
Describes the Oracle Virtual Private Database policy groups defined for the synonyms, tables, and views accessible to the current user |
|
Describes the security relevant columns of the security policies for the tables and views accessible to the current user |
|
Describes all Oracle Virtual Private Database security policies in the database. |
|
Describes all policy groups in the database. |
|
Describes all driving contexts in the database. Its columns are the same as those in |
|
Describes the security relevant columns of all security policies in the database |
|
Describes all Oracle Virtual Private Database security policies associated with objects owned by the current user. This view does not display the |
|
Describes the driving contexts defined for the synonyms, tables, and views owned by the current user. Its columns (except for |
|
Describes the security relevant columns of the security policies for the tables and views owned by the current user. Its columns (except for |
|
Describes the policy groups defined for the synonyms, tables, and views owned by the current user. This view does not display the |
|
Displays all the fine-grained security policies and predicates associated with the cursors currently in the library cache. This view is useful for finding the policies that were applied to a SQL statement. |
Tip:
In addition to these views, check the database trace file if you find errors in application that use Virtual Private Database policies. See Oracle Database Performance Tuning Guide for more information about trace files. TheUSER_DUMP_DEST
initialization parameter specifies the current location of the trace files. You can find the value of this parameter by issuing SHOW PARAMETER USER_DUMP_DEST
in SQL*Plus.