您好,登錄后才能下訂單哦!
本節簡單介紹了Oracle VPD。VPD用于實現精細化的權限管理。
What?
VPD的做法:VPD自動添加where子句到SQL語句上
影響的對象:table、view、synonym
涉及的語句:select、insert、update、index和delete
不支持:DDL
基本做法示例:
Benefits
Using Oracle Virtual Private Database with an Application Context
function
What
How
CREATE OR REPLACE FUNCTION hide_sal_comm (
BEGIN
— 設置敏感列輸出
創建數據表,設定謂詞為:username=’測試’ 創建函數 創建策略(select) 測試策略 創建策略(select、insert、update、delete) 測試策略
SELECT
FROM OE.ORDERS;
—>應用VPD
SELECT FROM OE.ORDERS
WHERE SALES_REP_ID = 159;
Security:不管用戶如何訪問數據,都可以確保精細化的訪問控制策略得到執行。
Simplicity:只需要在table、view上操作一次即可
Flexibility:select、insert、update、delete都可以有自己的策略
SELECT
FROM orders_tab
—>
SELECT FROM orders_tab
WHERE custno = SYS_CONTEXT (‘order_entry’, ‘cust_num’);
Components of an Oracle Virtual Private Database Policy
用于產生where子句(謂詞)
輸入參數:schema、object name
輸出參數:where子句(有效的)
Configuring an Oracle Virtual Private Database Policy
function需與object進行綁定,可通過配置policy實現綁定。
policy本身用于管理VPD function,同時可以進行精細化訪問控制,比如指定SQL語句類型或者策略影響的特定列。
Oracle提供了DBMS_RLS來進行策略管理:ADD、DROP、ENABLE/DISABLE…
例子:
SELECT fname, lname, ssn FROM emp;
—>
SELECT fname, lname, ssn FROM emp
WHERE ssn = ‘my_ssn’;
v_schema IN VARCHAR2,
v_objname IN VARCHAR2)
RETURN VARCHAR2 AS
con VARCHAR2 (200);
BEGIN
con := ‘deptno=30’;
RETURN (con);
END hide_sal_comm;
/
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;
/
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;
/
Tutorials
drop table t_vpd_1;
create table t_vpd_1(id int,username varchar2(20),name varchar2(30));
insert into t_vpd_1(id,username,name) values(1,'test','name1');
insert into t_vpd_1(id,username,name) values(2,'張三','name1');
insert into t_vpd_1(id,username,name) values(3,'測試','測試名稱1');
insert into t_vpd_1(id,username,name) values(4,'測試','測試名稱2');
commit;
CREATE OR REPLACE FUNCTION func_testvpd_1(
schemaname IN VARCHAR2,
tablename IN VARCHAR2
)
RETURN VARCHAR2
IS
ret VARCHAR2 (400);
BEGIN
ret := 'username = ''測試''';
RETURN ret;
END func_testvpd_1;
/
BEGIN
DBMS_RLS.DROP_POLICY (
object_schema => 'test',
object_name => 't_vpd_1',
policy_name => 'policy_t_vpd_1'
);
END;
/
BEGIN
DBMS_RLS.ADD_POLICY (
object_schema => 'test',
object_name => 't_vpd_1',
policy_name => 'policy_t_vpd_1',
function_schema => 'test',
policy_function => 'func_testvpd_1',
statement_types => 'select'
);
END;
/
-- 查詢
select * from t_vpd_1;
-- 插入
TEST-orcl@DESKTOP-V430TU3>create table t_vpd_2 as select * from t_vpd_1 where 1=2;
Table created.
TEST-orcl@DESKTOP-V430TU3>insert into t_vpd_2(id,username,name) select * from t_vpd_1;
2 rows created.
TEST-orcl@DESKTOP-V430TU3>delete from t_vpd_1;
4 rows deleted.
TEST-orcl@DESKTOP-V430TU3>
TEST-orcl@DESKTOP-V430TU3>update t_vpd_1 set name = 'test';
0 rows updated.
BEGIN
DBMS_RLS.DROP_POLICY (
object_schema => 'test',
object_name => 't_vpd_1',
policy_name => 'policy_t_vpd_1'
);
END;
/
BEGIN
DBMS_RLS.ADD_POLICY (
object_schema => 'test',
object_name => 't_vpd_1',
policy_name => 'policy_t_vpd_1',
function_schema => 'test',
policy_function => 'func_testvpd_1',
statement_types => 'select,insert,update,delete'
);
END;
/
insert into t_vpd_1(id,username,name) values(1,'test','name1');
insert into t_vpd_1(id,username,name) values(2,'張三','name1');
insert into t_vpd_1(id,username,name) values(3,'測試','測試名稱1');
insert into t_vpd_1(id,username,name) values(4,'測試','測試名稱2');
commit;
-- 查詢
TEST-orcl@DESKTOP-V430TU3>select * from t_vpd_1;
ID USERNAME NAME
---------- -------------------- ------------------------------
3 測試 測試名稱1
4 測試 測試名稱2
-- 插入
TEST-orcl@DESKTOP-V430TU3>drop table t_vpd_2 ;
Table dropped.
TEST-orcl@DESKTOP-V430TU3>create table t_vpd_2 as select * from t_vpd_1 where 1=2;
Table created.
TEST-orcl@DESKTOP-V430TU3>insert into t_vpd_2(id,username,name) select * from t_vpd_1;
2 rows created.
TEST-orcl@DESKTOP-V430TU3>update t_vpd_1 set name = 'test';
2 rows updated.
TEST-orcl@DESKTOP-V430TU3>delete from t_vpd_1;
2 rows deleted.
TEST-orcl@DESKTOP-V430TU3>
免責聲明:本站發布的內容(圖片、視頻和文字)以原創、轉載和分享為主,文章觀點不代表本網站立場,如果涉及侵權請聯系站長郵箱:is@yisu.com進行舉報,并提供相關證據,一經查實,將立刻刪除涉嫌侵權內容。