Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
![]() |
![]() |
Home -> Community -> Usenet -> c.d.o.misc -> Re: multiple row output from procedure
A copy of this was sent to "Fredrik Åkesson"
<fredrik.akesson_at_NOSPAMeng.ericsson.se>
(if that email address didn't require changing)
On Tue, 04 Aug 1998 11:04:05 +0200, you wrote:
>I need to create a procedure (or package?) that retrieves multiple rows
>from a table,
>i.e.
>CREATE PROCEDURE procname (first OUT VARCHAR2, last OUT VARCHAR2 )
>AS
>BEGIN
> SELECT firstname, lastname
> INTO first, last
> FROM tablename
>END;
>
>There will be a multiple row answer, but how do I handle the response?
>What datatypes should the outgoing variables be? Can I call the
>procedure in a single sql line?
>
>/Fredrik
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 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 );}
Thomas Kyte
tkyte_at_us.oracle.com
Oracle Government
Herndon VA
http://govt.us.oracle.com/ -- downloadable utilities
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 Tue Aug 04 1998 - 10:03:27 CDT
![]() |
![]() |