Re: How To DO? Stored procedures that return result sets.

From: Thomas Kyte <tkyte_at_us.oracle.com>
Date: Thu, 12 Nov 1998 15:26:35 GMT
Message-ID: <364afe13.7295640_at_192.86.155.100>


A copy of this was sent to Alex de Gaston <degaston_at_netwave.net> (if that email address didn't require changing) On Thu, 12 Nov 1998 06:22:05 -0600, you wrote:

>In Sybase I can write a stored procedure that will do the following:
>
>create procedure sp_mytest as
>
>select * from emp where salary<50000
>return 0
>
>The application calling the stored procedure will receive a result set
>with all employees making less than $50K.
>
>
>Is there any guide out there that can tell me how to do the same thing
>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;
}  

Thomas Kyte
tkyte_at_us.oracle.com
Oracle Government
Herndon VA

--
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 Thu Nov 12 1998 - 16:26:35 CET

Original text of this message