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 -> Re: Select from stored proc

Re: Select from stored proc

From: Thomas Kyte <tkyte_at_us.oracle.com>
Date: Fri, 22 Jan 1999 19:31:55 GMT
Message-ID: <36add225.101155273@192.86.155.100>


A copy of this was sent to arivlin_at_my-dejanews.com (if that email address didn't require changing) On Fri, 22 Jan 1999 18:55:16 GMT, you wrote:

>Hi, all,
>Here is a beginner's question:
>I want to write a stored proc that will do a bunch of preparation ( like set
>variables for example ) and then run some selects from a table.
>Here is a SYBASE example:
>create proc aaa ( @a int )
>as
>begin
> select @a = age from DBA where First_Name = 'Bob'
>
> select First_Name, Last_Name
> from DBA
> where Sex = 'F'
> and Age < @a
> and DB_Type = 'ORACLE'
>end
>
>
>This proc can be run by multiple users that share the same login
>simulteniously.
>How do I do it in ORACLE ? I can not write data to a permanent output table
>because it will get mixed up with other people who run the same proc, and I do
>not want to log results. Sometimes results could be huge 500K rows, in which
>case, I just want to return them to a client app. I do not want them to be
>stored in a table even temporarily for performance reasons.
>
>How do I do it in Oracle?
>

In short, it'll look like this:

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;
/

With 7.2 on up of the database you have cursor variables. Cursor variables are cursors opened by a pl/sql routine and fetched from by another application 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;
}

>Thank you
>Alex
>
>-----------== Posted via Deja News, The Discussion Network ==----------
>http://www.dejanews.com/ Search, Read, Discuss, or Start Your Own
 

Thomas Kyte
tkyte_at_us.oracle.com
Oracle Service Industries
Reston, VA USA

--
http://govt.us.oracle.com/ -- downloadable utilities  



Opinions are mine and do not necessarily reflect those of Oracle Corporation  

Anti-Anti Spam Msg: if you want an answer emailed to you, you have to make it easy to get email to you. Any bounced email will be treated the same way i treat SPAM-- I delete it. Received on Fri Jan 22 1999 - 13:31:55 CST

Original text of this message

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