Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
![]() |
![]() |
Home -> Community -> Usenet -> c.d.o.misc -> Re: How Do You Get Result Sets in Oracle8 SPs?
In article <7cpd2d$prn$1_at_camel25.mindspring.com>,
"dhmac" <dhmac_at_JUSTREMOVETHISmy-dejanews.com> wrote:
> I'm working on a project that is converting from Sybase to Oracle8. In
Sybase,
> the project uses numerous stored procedures to encapsulate all of the select
> statements. Now I've been told that Oracle SPs don't support result sets. I
> know Oracle7 cannot do it but was this ability added to Oracle8? If not, is
> there an easy way to simulate this in Oracle8?
>
> Thanks
>
>
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 );}
The following is thanks to micro_at_work.org (mark tomlinson)..
If you use ODBC here is a working example, but it requires the use of the 8.0.5.2.0 or later Oracle ODBC driver, and an 8.0.5 server.
'
' 1) Create a form with 1 Text control (Text1) and 1 List Control
(List1) and
' 1 Button (btnExecute).
' 2) The only code that you need is a Click method on your button.
Here is the Code.
'
'
Private Sub btnExecute_Click()
'PL/SQL Code '=========== ' 'CREATE OR REPLACE package reftest as ' cursor c1 is select ename from emp; ' type empCur is ref cursor return c1%ROWTYPE; ' Procedure GetEmpData(en in varchar2,EmpCursor in out empCur); 'END; ' ' 'CREATE OR REPLACE package body reftest as ' Procedure GetEmpData '(en in varchar2,EmpCursor in out empCur) is 'begin ' open EmpCursor for select ename from emp where ename LIKE en; 'end; 'end; ' Dim cn As New rdoConnection Dim qd As rdoQuery Dim rs As rdoResultset Dim cl As rdoColumn Static Number As Integer List1.Clear Number = 0 cn.Connect = "uid=scott; pwd=tiger; DSN=MSLANGORL;" 'enable the MS Cursor library cn.CursorDriver = rdUseOdbc 'Make the connection cn.EstablishConnection rdNoDriverPrompt sSQL = "{call RefTest.GetEmpData(?,?)}" Set qd = cn.CreateQuery("", sSQL) qd.rdoParameters(0).Type = rdTypeVARCHAR qd(0).Direction = rdParamInputOutput qd(0).Value = Text1.Text qd.rdoParameters(1).Type = rdTypeVARCHAR 'Dynamic or Keyset is meaningless here Set rs = qd.OpenResultset(rdOpenStatic) Do Debug.Print Debug.Print Do Until rs.EOF For Each cl In rs.rdoColumns If IsNull(cl.Value) Then List1.AddItem "(null)" ' Debug.Print " "; cl.Name; "NULL"; Error trap for null fields Else List1.AddItem cl.Value ' Debug.Print " "; cl.Name; " "; cl.Value; End If Next Debug.Print rs.MoveNext Loop Loop While rs.MoreResults cn.Close
End Sub
Thomas Kyte tkyte_at_us.oracle.com Oracle Service Industries Reston, VA USA--
-----------== Posted via Deja News, The Discussion Network ==---------- http://www.dejanews.com/ Search, Read, Discuss, or Start Your Own Received on Fri Mar 19 1999 - 19:51:16 CST
![]() |
![]() |