Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
Home -> Community -> Mailing Lists -> Oracle-L -> RE: how to grant selct on all the ables in schema
Try this . . . input is name of schema owner and who's being granted the rights. It grants full DML rights on all schema objects to a known user or role. Can be edited for "select only" rights on tables, if you want . . . -bill
/* SQL*PLUS SETTINGS */
SET ECHO OFF
SET VERIFY OFF
SET SERVEROUTPUT ON
/* VARIABLE DECLARATIONS */
ACCEPT p_owner PROMPT 'Enter the name of the object/schema owner: '
ACCEPT p_grantee PROMPT 'Enter the name of the user or role to receive
grants: '
/* BEGIN SCRIPT TEXT */
DECLARE
v_otype varchar2(30); v_oname varchar2(30); v_gtype varchar2(1); v_sprivs varchar2(50) := ' select '; v_tvprivs varchar2(50) := ' select, insert, update, delete ';no_grantee exception;
cursor get_objects_cursor is
select object_type, object_name from all_objects
where owner = upper('&p_owner')
and object_type in ( 'SEQUENCE', 'TABLE', 'VIEW')
order by object_type, object_name;
BEGIN
select decode(count(role),0,'X',1,'R')
into v_gtype
from dba_roles
where role = upper('&p_grantee');
if v_gtype = 'X' then
select decode(count(username),0,'X',1,'U') into v_gtype from dba_users where username = upper('&p_grantee');end if;
if v_gtype = 'X' then
raise no_grantee;
end if;
open get_objects_cursor;
loop
fetch get_objects_cursor into v_otype, v_oname;
exit when get_objects_cursor%notfound;
execute immediate ('revoke all on &p_owner..' || v_oname || ' from &p_grantee');
if v_otype = 'SEQUENCE' then
execute immediate ('grant ' || v_sprivs || ' on &p_owner..' || v_oname || '
to &p_grantee');
else
execute immediate ('grant ' || v_tvprivs || ' on &p_owner..' || v_oname ||
' to &p_grantee');
end if;
end loop;
close get_objects_cursor;
EXCEPTION WHEN no_grantee then
dbms_output.put_line('***********************************************'); dbms_output.put_line('IMPORTANT:'); dbms_output.put_line('The grantee specified, >>> &p_grantee <<< '); dbms_output.put_line('is neither a role nor a user in the database. ');dbms_output.put_line('Operation cancelled.');
dbms_output.put_line('***********************************************');
END;
/
/* END SCRIPT TEXT */
-----Original Message-----
Sent: Thu, January 31, 2002 2:45 AM
To: Multiple recipients of list ORACLE-L
Hi
something like this
Put it in a script file and you can replace the hardcoded schema & user
with &1 and &2 variables and call the script with variables.
@script userx schema
set pages 0
set feedback of
set lines 150
set trimspool on
set heading of
Spool grant.sql
select 'grant select on '||owner||'.'||table_name||'to userX;'
from dba_tables
where owner = 'SCHEMA';
spool off
@grant.sql
host rm grant.sql
Jack
kranti pushkarna <kranti_pushkarna_at_staarship.com>@fatcity.com on 31-01-2002 08:05:20
Please respond to ORACLE-L_at_fatcity.com
Sent by: root_at_fatcity.com
To: Multiple recipients of list ORACLE-L <ORACLE-L_at_fatcity.com> cc: (bcc: Jack van Zanen/nlzanen1/External/MEY/NL)
Hi all,
Is there anyway of granting select on all the tables in a schema in one shot.
Regards
Kranti Pushkarna
Project Leader
Tel: +91-22-6931557
Indien bovenstaand e-mailbericht niet aan u is gericht, verzoeken wij u vriendelijk doch dringend het e-mailbericht te retourneren aan de verzender en het origineel en eventuele kopieën te verwijderen en te vernietigen.
Ernst & Young hanteert bij de uitoefening van haar werkzaamheden algemene voorwaarden, waarin een beperking van aansprakelijkheid is opgenomen. De algemene voorwaarden worden u op verzoek kosteloos toegezonden.
If you are not the intended recipient of this communication please return the communication to the sender and delete and destroy all copies.
In carrying out its engagements, Ernst & Young applies general terms and conditions, which contain a clause that limits its liability. A copy of these terms and conditions is available on request free of charge.
-- Please see the official ORACLE-L FAQ: http://www.orafaq.com -- Author: INET: nlzanen1_at_EY.NL Fat City Network Services -- (858) 538-5051 FAX: (858) 538-5051 San Diego, California -- Public Internet access / Mailing Lists -------------------------------------------------------------------- To REMOVE yourself from this mailing list, send an E-Mail message to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from). You may also send the HELP command for other information (like subscribing). -- Please see the official ORACLE-L FAQ: http://www.orafaq.com -- Author: Magaliff, Bill INET: Bill.Magaliff_at_lendware.com Fat City Network Services -- (858) 538-5051 FAX: (858) 538-5051 San Diego, California -- Public Internet access / Mailing Lists -------------------------------------------------------------------- To REMOVE yourself from this mailing list, send an E-Mail message to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from). You may also send the HELP command for other information (like subscribing).Received on Thu Jan 31 2002 - 08:59:06 CST