Oracle如何找出一個表的間接授權信息?
2025-06-27 09:36 瀟湘隱者 閱讀(59) 評論(0) 收藏 舉報在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'
);

掃描上面二維碼關注我
如果你真心覺得文章寫得不錯,而且對你有所幫助,那就不妨幫忙“推薦"一下,您的“推薦”和”打賞“將是我最大的寫作動力!
本文版權歸作者所有,歡迎轉載,但未經作者同意必須保留此段聲明,且在文章頁面明顯位置給出原文連接.
浙公網安備 33010602011771號