Oracle FAQ Your Portal to the Oracle Knowledge Grid
HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US
 

Home -> Community -> Usenet -> c.d.o.server -> Re: executing a query in a Stored Procedure

Re: executing a query in a Stored Procedure

From: Thomas Kyte <tkyte_at_us.oracle.com>
Date: Thu, 24 Jun 1999 17:10:06 GMT
Message-ID: <37736654.480981@newshost.us.oracle.com>


A copy of this was sent to nealgran_at_my-deja.com (if that email address didn't require changing) On Thu, 24 Jun 1999 15:59:04 GMT, you wrote:

>Since my initial posting was vague and did not properly address the real
>issue I am interested in, I will rephrase my question in more detail.
>
> I am creating a general purpose SQL interpreter in java using JDBC to
>connect to various databases including Oracle. One problem that I have
>is that there is a facility in the JDBC API to perform an 'executeQuery'
>statement on a stored procedure. This facility works fine with
>SQLServer for example, but when I tried to test it with Oracle, I found
>that Oracles PL/SQL interface does not permit Stored Procedures to
>execute a query, and make the resultant table of that query available to
>the caller.
>
> From the responses I have gotten, and thru examples on the Oracle web
>site, I think may be able to use a cursor for this purpose. The
>implementation details are still vague to me, and if anyone can lend
>some insight, or point to a good reference on this topic, I would
>appreciate it.
>

[snip]

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

And the java to use this could be:

import java.sql.*;
import java.io.*;
import oracle.jdbc.driver.*;

class curvar
{
  public static void main (String args [])

                     throws SQLException, ClassNotFoundException
  {
      String driver_class = "oracle.jdbc.driver.OracleDriver";
      String connect_string = "jdbc:oracle:thin:@slackdog:1521:oracle8";

      String query = "begin :1 := sp_listEmp; end;";
      Connection conn;

      Class.forName(driver_class);
      conn = DriverManager.getConnection(connect_string, "scott", "tiger");

      CallableStatement cstmt = conn.prepareCall(query);
      cstmt.registerOutParameter(1,OracleTypes.CURSOR);
      cstmt.execute();
      ResultSet rset = (ResultSet)cstmt.getObject(1);

      while (rset.next ())
        System.out.println( rset.getString (1) );
      cstmt.close();

  }
}  

>Thanks
>
>-Neal Gran
>Metaserver Inc.
>check out http://www.mserver.com to see our revolutionary web
>application server technology
>
>
>In article <7krcta$g8j$1_at_nnrp1.deja.com>,
> nealgran_at_my-deja.com wrote:
>> When I try to perform a query in a stored procedure it does not
>compile.
>>
>> The PL/SQL syntax I used is as follows:
>>
>> Create Procedure GetInfo AS
>> BEGIN
>> select Field1 from MyTable;
>> END;
>>
>> Does this have to do with the handling of the resultant table from the
>> query? If I replace the query with a directive the Stored procedure
>> compiles.
>>
>> Sent via Deja.com http://www.deja.com/
>> Share what you know. Learn what you don't.
>>
>
>
>Sent via Deja.com http://www.deja.com/
>Share what you know. Learn what you don't.

--
See http://govt.us.oracle.com/~tkyte/ for my columns 'Digging-in to Oracle8i'... Current article is "Part I of V, Autonomous Transactions" updated June 21'st  

Thomas Kyte                   tkyte_at_us.oracle.com
Oracle Service Industries     Reston, VA   USA

Opinions are mine and do not necessarily reflect those of Oracle Corporation Received on Thu Jun 24 1999 - 12:10:06 CDT

Original text of this message

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