在Oracle中,如何让普通用户可以TRUNCATE其他用户的表?
用户1若要删除用户2的索引,则用户1需要有DROP ANY INDEX的权限。用户1若要TRUNCATE用户2的表,则用户1需要有DROP ANY TABLE的权限。但是,DROP ANY INDEX和DROP ANY TABLE的权限过大,一般不能赋予普通用户这2个权限,那么可以通过写存储过程来实现该功能,如下所示:
CREATE OR REPLACE PROCEDURE PRO_TRUNC_DROP_LHR(COMMAND IN VARCHAR2,
O_TYPE IN VARCHAR2,
OWNER IN VARCHAR2,
O_NAME IN VARCHAR2) AUTHID DEFINER AS
V_SQL VARCHAR2(4000);
BEGIN
IF UPPER(COMMAND) IN ('DROP', 'TRUNCATE') AND
UPPER(O_TYPE) IN ('TABLE', 'INDEX') THEN
V_SQL := COMMAND || ' ' || O_TYPE || ' ' || OWNER || '.' || O_NAME;
EXECUTE IMMEDIATE V_SQL;
END IF;
END PRO_TRUNC_DROP_LHR;
复制
使用示例如下所示:
创建用户1和用户2,分别赋予CONNECT和RESOURCE权限:
SQL> SHOW USER
USER is "SYS"
SQL>
SQL> CREATE USER LHR_U1 IDENTIFIED BY LHR_U1;
User created.
SQL> CREATE USER LHR_U2 IDENTIFIED BY LHR_U2;
User created.
SQL> GRANT CONNECT,RESOURCE TO LHR_U1;
Grant succeeded.
SQL> GRANT CONNECT,RESOURCE TO LHR_U2;
Grant succeeded.
复制
用户2创建表U2_T_LHR:
SQL> CONN LHR_U2/LHR_U2
Connected.
SQL> CREATE TABLE U2_T_LHR AS SELECT * FROM DUAL;
Table created.
SQL> SELECT * FROM U2_T_LHR;
D
-
X
SQL> CREATE INDEX IDX_U2_T_LHR ON U2_T_LHR(DUMMY);
Index created.
SQL>
SQL> GRANT SELECT,DELETE,UPDATE ON U2_T_LHR TO LHR_U1;
Grant succeeded.
复制
用户2创建存储过程并赋予用户1的执行权限:
SQL> CREATE OR REPLACE PROCEDURE PRO_TRUNC_DROP_LHR(COMMAND IN VARCHAR2,
2 O_TYPE IN VARCHAR2,
3 OWNER IN VARCHAR2,
4 O_NAME IN VARCHAR2) AUTHID DEFINER AS
5 V_SQL VARCHAR2(4000);
6 BEGIN
7 IF UPPER(COMMAND) IN ('DROP', 'TRUNCATE') AND
8 UPPER(O_TYPE) IN ('TABLE', 'INDEX') THEN
9 V_SQL := COMMAND || ' ' || O_TYPE || ' ' || OWNER || '.' || O_NAME;
10 EXECUTE IMMEDIATE V_SQL;
11 END IF;
12 END PRO_TRUNC_DROP_LHR;
13 /
Procedure created.
SQL> GRANT EXECUTE ON PRO_TRUNC_DROP_LHR TO LHR_U1;
Grant succeeded.
复制
用户1开始查询:
SQL> conn LHR_U1/LHR_U1
Connected.
SQL>
SQL> SELECT * FROM LHR_U2.U2_T_LHR;
D
-
X
SQL> TRUNCATE TABLE LHR_U2.U2_T_LHR;
TRUNCATE TABLE LHR_U2.U2_T_LHR
*
ERROR at line 1:
ORA-01031: insufficient privileges
SQL> DROP INDEX LHR_U2.IDX_U2_T_LHR;
DROP INDEX LHR_U2.IDX_U2_T_LHR
*
ERROR at line 1:
ORA-01418: specified index does not exist
SQL> DROP TABLE LHR_U2.U2_T_LHR;
DROP TABLE LHR_U2.U2_T_LHR
*
ERROR at line 1:
ORA-01031: insufficient privileges
复制
可以看到TRUNCATE、DROP都没有权限,下面采用存储过程删除:
SQL> EXEC LHR_U2.PRO_TRUNC_DROP_LHR('TRUNCATE','TABLE','LHR_U2','U2_T_LHR');
PL/SQL procedure successfully completed.
SQL> SELECT * FROM LHR_U2.U2_T_LHR;
no rows selected
SQL> EXEC LHR_U2.PRO_TRUNC_DROP_LHR('DROP','INDEX','LHR_U2','IDX_U2_T_LHR');
PL/SQL procedure successfully completed.
SQL> EXEC LHR_U2.PRO_TRUNC_DROP_LHR('DROP','TABLE','LHR_U2','U2_T_LHR');
PL/SQL procedure successfully completed.
SQL> SELECT * FROM LHR_U2.U2_T_LHR;
SELECT * FROM LHR_U2.U2_T_LHR
*
ERROR at line 1:
ORA-00942: table or view does not exist
SQL> CONN LHR_U2/LHR_U2
Connected.
SQL>
SQL> SELECT * FROM USER_INDEXES;
no rows selected
复制
可以看到已经正常删除了。
● 本文作者:小麦苗,只专注于数据库的技术,更注重技术的运用
● 作者博客地址:http://blog.itpub.net/26736162/abstract/1/
● 本系列题目来源于作者的学习笔记,部分整理自网络,若有侵权或不当之处还请谅解
● 版权所有,欢迎分享本文,转载请保留出处
● QQ:646634621 QQ群:230161599
● 题目解答若有不当之处,还望各位朋友批评指正,共同进步
长按下图识别二维码或微信扫描下图二维码来关注小麦苗的微信公众号:xiaomaimiaolhr,学习最实用的数据库技术。