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 Statement in Stored Procedure

Re: Select Statement in Stored Procedure

From: Thomas Kyte <tkyte_at_us.oracle.com>
Date: Mon, 26 Oct 1998 13:24:36 GMT
Message-ID: <363477f2.1716768@192.86.155.100>


A copy of this was sent to "Alex" <kahhoe_at_krdl.org.sg> (if that email address didn't require changing) On Mon, 26 Oct 1998 10:48:18 +0800, you wrote:

>hi Folks,
>
>I am a Visual C++ Developer and currently working on a project that require
>Oracle (Not my decision!)
>

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

>Actually I have a problem to share and ask. Is it true that Oracle Stored
>Procedure CANNOT return any recordset? I have tried to use SELECT but it
>keep complain that it must use SELECT ... INTO.. syntax. This would means
>it can only return at most one row. Am I right? I did some surfing and
>realize that other people mention that Oracle can return recordset by using
>Package or Collection. Can anyone experience here please share with us?
>
>Thanks you!
>
>
>
>Best Regards,
>Kah Hoe
>
>ps: Actually I have successfully implemented the above mention problem
>using SQL Server and I think Sybase also allow return of Recordset in Stored
>Procedure. Why doesn't Oracle implement this useful feature?
>
 

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 Mon Oct 26 1998 - 07:24:36 CST

Original text of this message

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