Title: RE: create view using DBMS.SQL

Do you have execute on dbms_sql granted to you?  You probably do since you can compile your procedure.

What Raj was eluding to is that you need the privilege create view granted to the procedure owner directly.  See below.


CREATE OR REPLACE PROCEDURE
PROC_REFRESH_VIEW
IS

 cursor_name INTEGER;
 cursor_id INTEGER;

BEGIN

cursor_name := DBMS_SQL.OPEN_CURSOR;
DBMS_SQL.PARSE(cursor_name,'CREATE OR REPLACE VIEW V_TEST AS '
||'SELECT * FROM USER_TABLES ',DBMS_SQL.NATIVE);

cursor_id := DBMS_SQL.EXECUTE(cursor_name);
DBMS_SQL.CLOSE_CURSOR(cursor_name);

END;
/

SQL> BEGIN
  2  PROC_rEFRESH_VIEW;
  3  END;
  4  /
BEGIN
*
ERROR at line 1:
ORA-01031: insufficient privileges
ORA-06512: at "SYS.DBMS_SYS_SQL", line 824
ORA-06512: at "SYS.DBMS_SQL", line 32
ORA-06512: at "LISA.PROC_REFRESH_VIEW", line 11
ORA-06512: at line 2


SQL> CONNECT SYS@FACD
Enter password: *********
Connected.
SQL> GRANT CREATE VIEW TO LISA;

Grant succeeded.

SQL> @LISAFACD
Connected.
*** You are now connected to FACD as LISA ***
SQL> BEGIN
  2  PROC_rEFRESH_VIEW;
  3  END;
  4  /

PL/SQL procedure successfully completed.

SQL> select count(*) from v_test;

  COUNT(*)
----------
         4

1 row selected.

-----Original Message-----
From: Donate Clothes [mailto:[EMAIL PROTECTED]]
Sent: Thursday, January 02, 2003 1:48 PM
To: Multiple recipients of list ORACLE-L
Subject: RE: create view using DBMS.SQL


I can create view in schema.  I don't know why it is not allowed me to
create view in DBMS_SQL within procedure.  Do I need additional privilege. 
Please give me some hints.  TIA Trung.

SQL> create or replace view mytest
  2  as
  3  select * from tbl_file_definitions;

View created.

SQL> select count(*) from mytest;

  COUNT(*)
----------
       641

SQL>






>From: "Koivu, Lisa" <[EMAIL PROTECTED]>
>Reply-To: [EMAIL PROTECTED]
>To: Multiple recipients of list ORACLE-L <[EMAIL PROTECTED]>
>Subject: RE: create view using DBMS.SQL
>Date: Thu, 02 Jan 2003 10:02:16 -0800
>
>Right.  Forgot that...
>
>-----Original Message-----
>Sent: Thursday, January 02, 2003 12:19 PM
>To: Multiple recipients of list ORACLE-L
>
>
>ummm directly?
>
>Raj
>______________________________________________________
>
>Rajendra Jamadagni              MIS, ESPN Inc.
>
>Rajendra dot Jamadagni at ESPN dot com
>
>Any opinion expressed here is personal and doesn't reflect that of ESPN
>Inc.
>
>
>QOTD: Any clod can have facts, but having an opinion is an art!
>
>-----Original Message-----
>Sent: Thursday, January 02, 2003 11:46 AM
>To: Multiple recipients of list ORACLE-L
>
>
>
>Is the create view privilege granted to the procedure owner?
>
>
>


_________________________________________________________________
MSN 8 with e-mail virus protection service: 2 months FREE*
http://join.msn.com/?page=features/virus

--
Please see the official ORACLE-L FAQ: http://www.orafaq.net
--
Author: Donate Clothes
  INET: [EMAIL PROTECTED]

Fat City Network Services    -- 858-538-5051 http://www.fatcity.com
San Diego, California        -- Mailing list and web hosting services
---------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: [EMAIL PROTECTED] (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).

Reply via email to