Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
![]() |
![]() |
Home -> Community -> Mailing Lists -> Oracle-L -> RE: Error in procedure with dba_users
You could try GRANT ANALYZE ANY TO SYSTEM
I didn't want to do that, in case we upgraded via export/import, in which case I might overlook that when SYSTEM got recreated, so I created a new DBA user and granted it the same privs as SYSTEM, plus the one above. We use this new account to do our DBMS_STATS work.
HTH! :)
Rich Jesse System/Database Administrator Rich.Jesse_at_qtiworld.com Quad/Tech International, Sussex, WI USA
-----Original Message-----
Sent: Thursday, March 21, 2002 3:49 PM
To: Multiple recipients of list ORACLE-L
Well, I guess, it means exactly what it says in the error message:
user SYSTEM does not have sufficient privileges to analyze some schema
(selected in ESQUEMAS cursor).
Igor Neyman, OCP DBA
ineyman_at_perceptron.com
Adary,
I am creating the procedure as system. I can select the table without no
problem.
I changed to all_users and worked fine, but the dbms_utility doesn't work.
Below is an example.
TIA Ramon.
CREATE OR REPLACE PROCEDURE GENERAR_ESTADISTICAS AS CURSOR ESQUEMAS IS
SELECT USERNAME ESQUEMA FROM ALL_USERS WHERE LENGTH(USERNAME <= 3 AND USERNAME != 'SYS';
('Generacion Estadisticas '||E.ESQUEMA, TO_CHAR(SYSDATE, 'DD/MM/YYYY'), NULL, 'Inicio');
-- EXECUTE (DBMS_UTILITY.ANALYZE_SCHEMA(E.ESQUEMA, 'COMPUTE')); -- INSERT INTO EJECUCION_PROCEDIMIENTOS (PROCEDIMIENTO, FECHA_INICIO, FECHA_FIN, ESTATUS) VALUES ('Generacion Estadisticas '||E.ESQUEMA, NULL, TO_CHAR(SYSDATE, 'DD/MM/YYYY'), 'Finalizo'); END LOOP; END; / SQL> EXECUTE GENERAR_ESTADISTICAS BEGIN GENERAR_ESTADISTICAS; END; * ERROR at line 1: ORA-20000: You have insufficient privileges for an object in this schema. ORA-06512: at "SYS.DBMS_UTILITY", line 258 ORA-06512: at "SYSTEM.GENERAR_ESTADISTICAS", line 19 ORA-06512: at line 1 SQL> EXECUTE DBMS_UTILITY.ANALYZE_SCHEMA('SCOTT', 'COMPUTE'); PL/SQL procedure successfully completed. SQL> sho user USER is "SYSTEM" -----Original Message----- <adary_at_mehish.co.il> Sent: Thursday, March 21, 2002 12:53 PM To: "Multiple recipients of list ORACLE-L" <ORACLE-L_at_fatcity.com> Tested it. You do not have permission for dba_users. You need to have role select_catalog_role. On 8.1.6.3.4 on NT. Yechiel Adar, Mehish Computer Services adary_at_mehish.co.il > -----Original Message----- > From: com.banilejas_at_codetel.net.do [SMTP:com.banilejas_at_codetel.net.do] > Sent: Thu, March 21, 2002 5:33 PM > To: Multiple recipients of list ORACLE-L > Subject: Error in procedure with dba_users > > Hi list, > > I have this procedure under the system user, and when try to create it > I get an error > > CREATE OR REPLACE PROCEDURE GENERAR_ESTADISTICAS AS > CURSOR ESQUEMAS IS > SELECT USERNAME ESQUEMA > FROM SYS.DBA_USERS > WHERE > USERNAME IN ('RAMON', 'SCOTT'); > BEGIN > FOR E IN ESQUEMAS > LOOP > DBMS_UTILITY.ANALYZE_SCHEMA(E.ESQUEMA, 'COMPUTE'); > END LOOP; > END; > > 3/8 PL/SQL: SQL Statement ignored > 4/16 PLS-00201: identifier 'SYS.DBA_USERS' must be declared > 11/4 PL/SQL: Statement ignored > 11/32 PLS-00364: loop index variable 'E' use is invalid > SQL> > > Any help . > > TIA > > Ramon E. Estevez -- Please see the official ORACLE-L FAQ: http://www.orafaq.com -- Author: Jesse, Rich INET: Rich.Jesse_at_qtiworld.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-LReceived on Thu Mar 21 2002 - 16:13:23 CST
(or the name of mailing list you want to be removed from). You may
also send the HELP command for other information (like subscribing).
![]() |
![]() |