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

Home -> Community -> Usenet -> c.d.o.misc -> Dynamic stored procedures with sample10.pc

Dynamic stored procedures with sample10.pc

From: Arun Jamwal <arun_at_quality.com>
Date: Tue, 06 Oct 1998 11:11:05 -0700
Message-ID: <361A5D39.7E970252@quality.com>


Hi,
I have one question regarding stored procedures and pro*c sample10 application interface. I was going through earlier news group post (dejanews archive) regarding reference cursors. I am wondering how do I execute such stored procedure/function which has a SELECT statement using sample10? I am attaching the two earlier replies from Thomas Kyte for the reference.

The following syntax doesn't seem to work for the reference cursor stored procedure:

SQL> begin foo_proc( :x ); end;
  2 /
======>Works fine

SQL> begin ; sp_ListEmp(); end;
  2 /
======> Doesn't work

Thanks,
Arun.


....
....
....

or pl/sql routine (in 7.3 pl/sql routines can fetch from cursor variables as
well as open them). The cursor variables are opened with the privelegs of the
owner of the procedure and behave just like they were completely contained
within the pl/sql routine. It uses the inputs to decide what database it will
run a query on.

Here is an example:

create or replace package types
as

    type cursorType is ref cursor;
end;
/

create or replace function sp_ListEmp return types.cursortype as

    l_cursor types.cursorType;
begin

    open l_cursor for select ename, empno from emp order by ename;

    return l_cursor;
end;
/

REM SQL*Plus commands to use a cursor variable

variable c refcursor
exec :c := sp_ListEmp
print c


and the Pro*c to use this would look like:

static void process()
{
EXEC SQL BEGIN DECLARE SECTION;
    SQL_CURSOR my_cursor;

    VARCHAR     ename[40];
    int         empno;

EXEC SQL END DECLARE SECTION;     EXEC SQL WHENEVER SQLERROR DO sqlerror_hard();

    EXEC SQL ALLOCATE :my_cursor;

    EXEC SQL EXECUTE BEGIN
        :my_cursor := sp_listEmp;
    END; END-EXEC;     for( ;; )
    {

        EXEC SQL WHENEVER NOTFOUND DO break;
        EXEC SQL FETCH :my_cursor INTO :ename, empno;

        printf( "'%.*s', %d\n", ename.len, ename.arr, empno );
    }
    EXEC SQL CLOSE :my_cursor;
}

....
....
....

You do not have to change sample10 at ALL to do dynamic pl/sql. It already
does it. Consider:

$ ./sample10

username: scott
password: tiger

Connected to ORACLE as user scott.

SQL> create table foo ( x int );

SQL> select * from foo;

X

0 rows processed.

SQL> create procedure foo_proc
  2 as
  3 begin
  4 insert into foo values ( 1 );
  5 end;
  6 /

SQL> begin
  2 foo_proc;
  3 end;
  4 /

SQL> select * from foo;

X

   1

1 row processed.

SQL> so using sample10 (not sqlplus) I can create a table, create a procedure

that works on the table and execute the procedure and then show the output.
In fact, we can dynamically do the above with bind variables and all, consider:

SQL> create or replace procedure foo_proc( val in number )   2 as
  3 begin
  4 insert into foo values ( val );
  5 end;
  6 /

SQL> begin foo_proc( :x ); end;
  2 /

Enter value for bind variable X: 55

SQL> select * from foo;

X

   1
  55

2 rows processed.

SQL> --
Thanks,

    Thomas Kyte
 tkyte_at_us.oracle.com

    Oracle Government Education & Health     Herndon, VA


Received on Tue Oct 06 1998 - 13:11:05 CDT

Original text of this message

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