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: How to execute a procedure in a package ? (newbie)

Re: How to execute a procedure in a package ? (newbie)

From: Thomas Kyte <tkyte_at_us.oracle.com>
Date: Thu, 24 Sep 1998 19:32:38 GMT
Message-ID: <36129d6d.89176589@192.86.155.100>


A copy of this was sent to long.pham_at_ips-sendero.com (Long Pham) (if that email address didn't require changing) On 24 Sep 1998 18:29:17 GMT, you wrote:

>Hi,
>
>I have the following package defined :
>
>CREATE OR REPLACE PACKAGE Customers
>AS
> TYPE tcus_nbr IS TABLE OF VARCHAR2(20)
> INDEX BY BINARY_INTEGER;
> TYPE tful_nme IS TABLE OF VARCHAR2(35)
> INDEX BY BINARY_INTEGER;
> TYPE ttin IS TABLE OF VARCHAR2(9)
> INDEX BY BINARY_INTEGER;
>
> PROCEDURE allcusts
> (cus_nbr OUT tcus_nbr,
> ful_nme OUT tful_nme,
> tin OUT tTin);
>END Customers;
>
>CREATE OR REPLACE PACKAGE BODY Customers
>AS
>
>
> PROCEDURE allcusts
> (cus_nbr OUT tcus_nbr,
> ful_nme OUT tful_nme,
> tin OUT ttin)
> IS
> CURSOR customer_cur IS
> SELECT CUS_NBR, FUL_NME, TIN
> FROM CUST;
>
> custcount NUMBER DEFAULT 1;
>
> BEGIN
> FOR singleperson IN customer_cur
> LOOP
> cus_nbr(custcount) := singleperson.cus_nbr;
> ful_nme(custcount) := singleperson.ful_nme;
> tin(custcount) := singleperson.tin;
> custcount := custcount + 1;
> END LOOP;
> END;
>
>END;
>
>How do I go about executing the allcusts procedure from the command line in
>SQLPlus ? Any reply will be much appreciated. Thanks.
>
>Long Pham

SQL> declare
   >     l_cus_nbr customers.tcus_nbr;
   >     l_ful_nme customers.tful_nme;
   >     l_tin     customers.ttin;
   > begin
   >     customers.allcusts( l_cus_nbr, l_ful_nme, l_tin );
   > end;
   > /
   

and if you wanted to print them out, it would look like:

SQL> set serveroutput on
SQL> declare
   >     l_cus_nbr customers.tcus_nbr;
   >     l_ful_nme customers.tful_nme;
   >     l_tin     customers.ttin;
   > begin
   >     customers.allcusts( l_cus_nbr, l_ful_nme, l_tin );
         for i in 1 .. l_cus_nbr.count loop
             dbms_output.put_line( l_cus_nbr(i) || ','|| l_ful_nme(i) );
         end loop;

   > end;
   > /

but it looks like what you really want to do is read about cursor variables. You are apparently trying to return a result set from a stored procedure and cursor variables would be the more correct (and efficient) way to do this.

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 Sep 24 1998 - 14:32:38 CDT

Original text of this message

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