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: Retrieving Multiple ROWS wITH pl/sql

Re: Retrieving Multiple ROWS wITH pl/sql

From: Thomas Kyte <tkyte_at_us.oracle.com>
Date: 1997/05/12
Message-ID: <337a343c.5788533@newshost>#1/1

On 9 May 1997 23:45:08 GMT, Marc Baime <mbaime_at_gte.net> wrote:

>I have a PL/SQL question. I have a client server architecture which
>entails using a module to execute stored procedures on the database and
>returning multiple rows to the module which invokes the stored
>procedures.
> I do not know at compile time how many rows will be returned to my
>procedure-invoking module so I don't believe that I can use the
>array-type
>to pass the data back to the invoking module without creating a static
>array with a size at least as large as my largest possible retuned set
>of rows (PLEASE correct me if I am wrong). A constraint of the
>architecture is that the executing modules are not permitted to do
>anything but invoke procedures i.e. I can't open a cursor and retrieve
>rows in the executing module...I need the procedure to return them as a
>group or I need to invoke the procedure multiple times.
>I know these constraints are very restrictive but I need to work within
>them. My question is this:
>What is the best method for me to retrieve multiple rows by invoking a
>PL/SQL procedure/package from my module?
>We are really struggling with this issue and would appreciate any
>responses.
>

You don't mention a database version but with 7.2 and 7.3 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 a 7.2 / 7.3 example in SQL*Plus and PRO*C

create or replace package empCurType
as

        cursor c1 is select ename, mgr, dept.deptno, dname, loc from emp, dept;

        type empCur is ref cursor return c1%rowtype;

	procedure open_cursor( p_cursor in out empCur, 
						   p_deptno in     number );

end;
/
show errors

create or replace package body empCurType as

procedure open_cursor( p_cursor in out empcur, p_deptno in number ) is
begin

	if ( p_deptno in ( 10, 20 ) ) then	-- open local query
		open p_cursor for
			select ename, mgr, dept.deptno, dname, loc 
		      from emp, dept
			 where emp.deptno = dept.deptno and dept.deptno = p_deptno;
	else
		open p_cursor for
			select ename, mgr, dept.deptno, dname, loc 
		      from emp_at_aria.world, dept_at_aria.world
			 where emp.deptno = dept.deptno and dept.deptno = p_deptno;
	end if;

end open_cursor;

end empCurType;
/
show errors

REM --------------- SQL*Plus using RefCursor to display results ------

variable C refcursor
exec empCurType.open_cursor( :C, 10 )

print C

REM ----------- PRO*C  Getting the cursor ------------------
REM
REM And then the pro*c would look like 'normal' pro*c code except that the EXEC REM SQL OPEN Cursor statement would now be a pl/sql call as follows: REM
REM
REM static void process()
REM {
REM EXEC SQL BEGIN DECLARE SECTION;
REM 	typedef char asciiz;
REM 	EXEC SQL TYPE asciiz IS STRING(100);
REM 	SQL_CURSOR	my_cursor;
REM 	asciiz		ename[40];
REM 	int			mgr;
REM 	short		mgr_i;
REM 	int			deptno;
REM 	asciiz		dname[50];
REM 	asciiz		loc[50];
REM 	int			i;

REM EXEC SQL END DECLARE SECTION;
REM
REM EXEC SQL WHENEVER SQLERROR DO sqlerror_hard(); REM
REM
REM EXEC SQL ALLOCATE :my_cursor;
REM
REM 	EXEC SQL EXECUTE BEGIN empCurType.open_cursor( :my_cursor, 10 ); end;
REM 	END-EXEC;
REM 
REM 	for( ;; )
REM 	{
REM 		EXEC SQL WHENEVER NOTFOUND DO BREAK;
REM 		EXEC SQL FETCH :my_cursor 
REM 			INTO :ename, :mgr:mgr_i, :deptno, :dname, :loc;
REM 	
REM 		printf( "%s, %d, %d, %s, %s\n", 
REM 				ename, mgr_i?-1:mgr, deptno, dname, loc );
REM 	}
REM 	EXEC SQL CLOSE :my_cursor;

REM }
>Please email responses to either email addresss below.
>
>Thanks for your time & Regards...Marc Baime
>
>--
>mbaime_at_gte.net
>marc.baime_at_telops.gte.com
>813-987-1752
>
>I have kept hidden in the instep arch
>Of an old cedar at the waterside
>A broken drinking goblet like the Grail
>Under a spell so the wrong ones can't find it
>So can't get saved...
>
>Robert Frost - Directive
>

Thomas Kyte
tkyte_at_us.oracle.com
Oracle Government
Bethesda MD

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



Opinions are mine and do not necessarily reflect those of Oracle Corporation Received on Mon May 12 1997 - 00:00:00 CDT

Original text of this message

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