在Oracle數據庫中, 如果需要找出一張表授權給了哪一個用户,這個比較簡單的,如果有一些視圖引用了這張表,然後這張視圖授權給了其它用户的話, 那麼這也屬於這張表的授權信息,如果也要找出這類信息,那麼如何找出來這些信息呢?
下面簡單看一個例子, 在數據庫中存在三個用户T1, T2, T3, 假設T1用户將表T1.TEST的查詢權限授予了用户T2.
create user t1 identified by t123456;
create user t2 identified by t234561;
create user t3 identified by t345612;
alter user t1 quota unlimited on users;
alter user t2 quota unlimited on users;
alter user t3 quota unlimited on users;
grant connect, resource to t1;
grant connect, resource to t2;
grant connect, resource to t3;
grant create view to t2;
grant create view to t3;
具體授權操作如下所示:
SQL> show user;
USER is "T1"
SQL> create table test(id number(10), name varchar2(30));
Table created.
SQL> insert into test
2 select 1, 'k1' from dual union all
3 select 2, 'k2' from dual;
2 rows created.
SQL> commit;
Commit complete.
SQL>
SQL> grant select on test to t2;
Grant succeeded
那麼此時查看關於表TEST的授權信息如下所示:
SET LINESIZE 820;
COL GRANTEE FOR A12
COL OWNER FOR A12
COL TABLE_NAME FOR A12
COL GRANTOR FOR A12
COL PRIVILEGE FOR A12
SELECT OWNER, TABLE_NAME, GRANTOR , GRANTEE, PRIVILEGE, GRANTABLE, TYPE
FROM DBA_TAB_PRIVS WHERE TABLE_NAME='TEST';
SQL> show user;
USER is "SYS"
SQL> SET LINESIZE 820;
SQL> COL GRANTEE FOR A12
SQL> COL OWNER FOR A12
SQL> COL TABLE_NAME FOR A12
SQL> COL GRANTOR FOR A12
SQL> COL PRIVILEGE FOR A12
SQL> SELECT OWNER, TABLE_NAME, GRANTOR , GRANTEE, PRIVILEGE, GRANTABLE, TYPE
2 FROM DBA_TAB_PRIVS WHERE TABLE_NAME='TEST';
OWNER TABLE_NAME GRANTOR GRANTEE PRIVILEGE GRA TYPE
------------ ------------ ------------ ------------ ------------ --- ------------------------
T1 TEST T1 T2 SELECT NO TABLE
SQL>
如果用户T1將表TEST的查詢權限授予了用户T2,並且使用了選項GRANT OPTION的話
SQL> show user;
USER is "T1"
SQL> grant select on test to t2 with grant option;
Grant succeeded.
SQL>
那麼此時,如果在T2用户下面創建一個視圖,引用表TEST, 然後將視圖T2.V_TEST的查詢權限授權給了用户T3.
SQL> show user;
USER is "T2"
SQL> create or replace view v_test
2 as
3 select name from t1.test;
View created.
SQL> grant select on t2.v_test to t3;
Grant succeeded.
SQL>
此時用户T3就相當間接擁有了表TEST的查詢權限. 如下所示:
SQL> show user;
USER is "T3"
SQL> select * from t2.v_test;
NAME
------------------------------
k1
k2
SQL>
但是,我們用上面的SQL來查詢一下表TEST授予了哪些用户.如下所示, 這個查詢結果不能體現表TEST間接授權給了用户T3
SQL> show user;
USER is "SYS"
SQL> SET LINESIZE 820;
SQL> COL GRANTEE FOR A12
SQL> COL OWNER FOR A12
SQL> COL TABLE_NAME FOR A12
SQL> COL GRANTOR FOR A12
SQL> COL PRIVILEGE FOR A12
SQL> SELECT OWNER, TABLE_NAME, GRANTOR , GRANTEE, PRIVILEGE, GRANTABLE, TYPE
2 FROM DBA_TAB_PRIVS WHERE TABLE_NAME='TEST';
OWNER TABLE_NAME GRANTOR GRANTEE PRIVILEGE GRA TYPE
------------ ------------ ------------ ------------ ------------ --- ------------------------
T1 TEST T1 T2 SELECT YES TABLE
SQL>
那麼問題來了,如何查詢這種情況下的授權呢? 其實我們可以用下面SQL實現這個需求.如下所示:
SET LINESIZE 820
COL OWNER FOR A10
COL TABLE_NAME FOR A16;
COL GRANTOR FOR A16
COL GRANTEE FOR A16
COL PRIVILEGE FOR A8;
SELECT OWNER, TABLE_NAME, GRANTOR , GRANTEE, PRIVILEGE, GRANTABLE, TYPE
FROM DBA_TAB_PRIVS
WHERE TABLE_NAME=UPPER(TRIM('&tb_name'))
UNION ALL
SELECT OWNER, TABLE_NAME, GRANTOR , GRANTEE, PRIVILEGE, GRANTABLE, TYPE
FROM DBA_TAB_PRIVS
WHERE TABLE_NAME IN(
SELECT NAME FROM dba_dependencies WHERE
REFERENCED_NAME=UPPER(TRIM('&tb_name')) AND TYPE='VIEW'
);