Oracle FAQ Your Portal to the Oracle Knowledge Grid
HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US
 

Home -> Community -> Mailing Lists -> Oracle-L -> RE: Privilege to be abl to truncate another user's table

RE: Privilege to be abl to truncate another user's table

From: Jacques Kilchoer <Jacques.Kilchoer_at_quest.com>
Date: Wed, 18 Feb 2004 17:23:55 -0800
Message-ID: <B5C5F99D765BB744B54FFDF35F602621033DAEEA@irvmbxw02>


Another advantage is that, since the TRUNCATE_TABLE is created with authid current_user, it will allow USERB to truncate table USERC.TABLE_NAME even if access is granted through a role, or through a role from another role and so on, something that can be tedious to check in a stored procedure. Though I notice that the previous version I included had an unnecessary rollback. How embarassing! The better version:

create or replace procedure do_truncate (table_owner_in varchar2, table_name_in varchar2) is
begin

   execute immediate 'truncate table "' || table_owner_in || '"."'

      || table_name_in || '"' ;
end do_truncate ;
/
create or replace procedure truncate_table

   (table_owner_in varchar2, table_name_in varchar2)    authid current_user
is
begin

   execute immediate 'delete from "' || table_owner_in || '"."' || table_name_in

      || '" where rownum < 1' ;
   do_truncate (table_owner_in, table_name_in) ; end truncate_table ;
/

> -----Original Message-----
> From: oracle-l-bounce_at_freelists.org
> [ mailto:oracle-l-bounce_at_freelists.org]On Behalf Of John Flack
> Sent: mardi, 17. février 2004 08:10
> To: oracle-l_at_freelists.org
> Subject: RE: Privilege to be abl to truncate another user's table
>
>
> I like your implementation - find out if the user has delete
> privilege =
> by trying to do a delete. Mine does a SELECT on
> ALL_TAB_PRIVS for this =
> and so is less straightforward.
>
> -----Original Message-----
> From: Jacques Kilchoer [ mailto:Jacques.Kilchoer_at_quest.com]
> Sent: Friday, February 13, 2004 9:16 PM
> To: oracle-l_at_freelists.org
> Subject: RE: Privilege to be abl to truncate another user's table
>
>
> I hate to steal someone else's thunder, but I wrote something
> a while =
> ago that does exactly the same thing, so I will take the liberty of =
> posting it here.
> Create two procedures owned by USERA. USERA has DROP ANY TABLE =
> privilege.
> grant execute on TRUNCATE_TABLE to USERB ;
>
> USERB has DELETE privilege on USERC.TABLENAME ;
>
> then USERB can say
> execute usera.truncate_table ('USERC', 'TABLENAME')
>
> create or replace procedure do_truncate (table_owner_in varchar2, =
> table_name_in varchar2)
> is
> begin
> execute immediate 'truncate table "' || table_owner_in || '"."'
> || table_name_in || '"' ;
> end do_truncate ;
> /
> create or replace procedure truncate_table
> (table_owner_in varchar2, table_name_in varchar2)
> authid current_user
> is
> begin
> execute immediate 'delete from "' || table_owner_in || '"."' || =
> table_name_in
> || '" where rownum < 2' ;
> rollback ;
> do_truncate (table_owner_in, table_name_in) ;
> end truncate_table ;
> /



Please see the official ORACLE-L FAQ: http://www.orafaq.com

To unsubscribe send email to: oracle-l-request_at_freelists.org put 'unsubscribe' in the subject line.
--
Archives are at http://www.freelists.org/archives/oracle-l/
FAQ is at http://www.freelists.org/help/fom-serve/cache/1.html
-----------------------------------------------------------------
Received on Wed Feb 18 2004 - 19:23:55 CST

Original text of this message

HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US