Result Sets from Stored Procedures In Oracle
A frequently asked question is:
I'd like to know whether ORACLE supports procedures (functions) which
returns result sets.
The answer is most definitely yes. 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;
/
examples for SQLPlus, Pro*C, Java/JDBC, ODBC, ADO/ASP, DBI Perl and OCI follow:
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();
}
}
The following is thanks to marktoml@hotmail.com (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
And now, for a full ASP example (thanks to Jim Hoien and John Durst )
<%@ Language=VBScript %>
<!--#INCLUDE VIRTUAL="/ADOVBS.INC" -->
<%
' This demonstration draws heavily from the information contained in the article at
' http://govt.us.oracle.com/~tkyte/ResultSets/index.html
' with special attention to the details provided by Mark Tomlinson.
' Make sure you have the correct Oracle ODBC driver so it will support Ref Cursors.
'
'
' This demonstration was a joint project by Jim Hoien (jhoien@yahoo.com) and John Durst (jpdurst@yahoo.com)
'
' These are the statements used on the Oracle server:
'
' /*******************************************************************************************/
' /* Create the EMP demo table and populate. (extracted from Oracle's provided demobld.sql) */
' /*******************************************************************************************/
'
' CREATE TABLE EMP
' (EMPNO NUMBER(4) NOT NULL,
' ENAME VARCHAR2(10),
' JOB VARCHAR2(9),
' MGR NUMBER(4),
' HIREDATE DATE,
' SAL NUMBER(7,2),
' COMM NUMBER(7,2),
' DEPTNO NUMBER(2));
'
' INSERT INTO EMP VALUES
' (7369,'SMITH','CLERK',7902,'17-DEC-80',800,NULL,20);
' INSERT INTO EMP VALUES
' (7499,'ALLEN','SALESMAN',7698,'20-FEB-81',1600,300,30);
' INSERT INTO EMP VALUES
' (7521,'WARD','SALESMAN',7698,'22-FEB-81',1250,500,30);
' INSERT INTO EMP VALUES
' (7566,'JONES','MANAGER',7839,'2-APR-81',2975,NULL,20);
' INSERT INTO EMP VALUES
' (7654,'MARTIN','SALESMAN',7698,'28-SEP-81',1250,1400,30);
' INSERT INTO EMP VALUES
' (7698,'BLAKE','MANAGER',7839,'1-MAY-81',2850,NULL,30);
' INSERT INTO EMP VALUES
' (7782,'CLARK','MANAGER',7839,'9-JUN-81',2450,NULL,10);
' INSERT INTO EMP VALUES
' (7788,'SCOTT','ANALYST',7566,'09-DEC-82',3000,NULL,20);
' INSERT INTO EMP VALUES
' (7839,'KING','PRESIDENT',NULL,'17-NOV-81',5000,NULL,10);
' INSERT INTO EMP VALUES
' (7844,'TURNER','SALESMAN',7698,'8-SEP-81',1500,0,30);
' INSERT INTO EMP VALUES
' (7876,'ADAMS','CLERK',7788,'12-JAN-83',1100,NULL,20);
' INSERT INTO EMP VALUES
' (7900,'JAMES','CLERK',7698,'3-DEC-81',950,NULL,30);
' INSERT INTO EMP VALUES
' (7902,'FORD','ANALYST',7566,'3-DEC-81',3000,NULL,20);
' INSERT INTO EMP VALUES
' (7934,'MILLER','CLERK',7782,'23-JAN-82',1300,NULL,10);
'
' /*******************************************************************************************/
' /* Create a packaged procedure that accepts a department number and returns the employees. */
' /* [Note: A standalone procedure will not work, it must be a packaged procedure!] */
' /*******************************************************************************************/
'
' CREATE OR REPLACE
' PACKAGE DEPARTMENT AS
' TYPE CURSOR_TYPE IS REF CURSOR;
' PROCEDURE GET_EMPS (I_DEPTNO IN NUMBER,
' O_RESULT_SET OUT CURSOR_TYPE);
' END;
' /
' CREATE OR REPLACE
' PACKAGE BODY DEPARTMENT AS
' PROCEDURE GET_EMPS (I_DEPTNO IN NUMBER,
' O_RESULT_SET OUT CURSOR_TYPE)
' AS
' BEGIN
' OPEN O_RESULT_SET FOR
' SELECT EMPNO, ENAME
' FROM EMP
' WHERE DEPTNO = I_DEPTNO;
' END;
' END;
' /
%>
<HTML>
<HEAD>
<TITLE>Oracle ADO Test</TITLE>
</HEAD>
<BODY>
<H2>Test of ADO and Oracle Stored Procedures using Ref Cursors</H2>
<%
Dim objConn
Dim connString
Dim cmdStoredProc
Dim param1
Dim testDeptNo
testDeptNo = 10
'testDeptNo = 20
'testDeptNo = 30
set objConn = server.createobject("adodb.connection")
' System DSN connection
' Replace the values below with your own
connString = "DSN=<YourDSN>;UID=<YourUserName>;PWD=<YourPassword>"
objConn.Open connString
Set cmdStoredProc = Server.CreateObject ("ADODB.Command")
Set cmdStoredProc.ActiveConnection = objConn
cmdStoredProc.CommandText = "Department.Get_Emps"
cmdStoredProc.CommandType = adCmdStoredProc
Set param1 = cmdStoredProc.CreateParameter ("Dept_ID", adInteger, adParamInput)
cmdStoredProc.Parameters.Append param1
param1.Value = testDeptNo
Set rs = cmdStoredProc.Execute
Response.Write ("<h3>Employees in Department # " & testDeptNo & "</h3>" & vbCrLf)
Response.Write ("<p>" & vbCrLf)
Response.Write ("<table>" & vbCrLf)
Response.Write ("<tr>" & vbCrLf)
Response.Write ("<th>Emp #</th>" & vbCrLf)
Response.Write ("<th>Name</th>" & vbCrLf)
Response.Write ("</tr>" & vbCrLf)
While (Not rs.EOF)
Response.Write ("<tr>" & vbCrLf)
Response.Write ("<td>" & rs (0) & "</td>" & vbCrLf)
Response.Write ("<td>" & rs (1) & "</td>" & vbCrLf)
Response.Write ("</tr>" & vbCrLf)
rs.MoveNext
Wend
Response.Write ("</table>" & vbCrLf)
rs.Close
objConn.Close
Set rs = nothing
Set param1 = nothing
Set cmdStoredProc = nothing
Set objConn = nothing
%>
</BODY>
</HTML>
And the following is thanks to Brett Rosen :
I noticed that you didn't have an OCI entry
on http://osi.oracle.com/~tkyte/ResultSets/index.html .
Here is OCI code to do this (Oracle 81) if you want to include it on
that page.
Some error checking and cleanup has been removed, but the below should
work. (once dbname has been replaced appropriately)
Brett
int main(int argc, char* argv[])
{
OCIError* pOciError;
char* pConnectChar = "dbname";
char* pUsernameChar = "scott";
char* pPasswordChar = "tiger";
int answer;
OCIStmt* pOciStatement;
char* sqlCharArray = "BEGIN :success := sp_ListEmp; END;";
int id;
char ename[40];
OCIEnv* g_pOciEnvironment = NULL;
OCIServer* g_pOciServer = NULL;
OCISession* g_pOciSession = NULL;
OCISvcCtx* g_pOciServiceContext = NULL;
sb2* pIndicator=0;
sb2* pIndicator2=0;
sb2* pIndicator3=0;
OCIDefine* pOciDefine;
OCIDefine* pOciDefine2;
OCIBind* pBind;
OCIStmt* cursor;
answer = OCIInitialize(OCI_THREADED, NULL, NULL, NULL, NULL);
answer = OCIEnvInit(&g_pOciEnvironment, OCI_DEFAULT, 0, NULL);
answer = OCIHandleAlloc(g_pOciEnvironment, (void **)&pOciError, OCI_HTYPE_ERROR, 0, NULL);
answer = OCIHandleAlloc(g_pOciEnvironment, (void **)&g_pOciSession, OCI_HTYPE_SESSION, 0, NULL);
answer = OCIHandleAlloc(g_pOciEnvironment, (void **)&g_pOciServer, OCI_HTYPE_SERVER, 0, NULL);
answer = OCIHandleAlloc(g_pOciEnvironment, (void **)&g_pOciServiceContext, OCI_HTYPE_SVCCTX, 0, NULL);
answer = OCIServerAttach(g_pOciServer, pOciError, (unsigned char *)pConnectChar, strlen(pConnectChar),
OCI_DEFAULT);
answer = OCIAttrSet(g_pOciSession, OCI_HTYPE_SESSION, (unsigned char *)pUsernameChar, strlen(pUsernameChar),
OCI_ATTR_USERNAME, pOciError);
answer = OCIAttrSet(g_pOciSession, OCI_HTYPE_SESSION, (unsigned char *)pPasswordChar, strlen(pPasswordChar),
OCI_ATTR_PASSWORD, pOciError);
answer = OCIAttrSet(g_pOciServiceContext, OCI_HTYPE_SVCCTX, g_pOciServer, 0, OCI_ATTR_SERVER, pOciError);
answer = OCIAttrSet(g_pOciServiceContext, OCI_HTYPE_SVCCTX, g_pOciSession, 0, OCI_ATTR_SESSION, pOciError);
answer = OCISessionBegin(g_pOciServiceContext, pOciError, g_pOciSession, OCI_CRED_RDBMS, OCI_DEFAULT);
answer = OCIHandleAlloc(g_pOciEnvironment, (void **)(&pOciStatement), OCI_HTYPE_STMT, 0, NULL);
answer = OCIStmtPrepare(pOciStatement, pOciError, (unsigned char *)sqlCharArray, strlen(sqlCharArray),
OCI_NTV_SYNTAX, OCI_DEFAULT);
answer = OCIHandleAlloc(g_pOciEnvironment, (void **)(&cursor), OCI_HTYPE_STMT, 0, NULL);
answer = OCIBindByPos(pOciStatement,&pBind, pOciError, 1, &cursor, 0,SQLT_RSET,
pIndicator2, 0,NULL, 0,0,OCI_DEFAULT);
answer = OCIStmtExecute(g_pOciServiceContext, pOciStatement, pOciError, 1, 0, NULL, NULL,
OCI_COMMIT_ON_SUCCESS);
answer = OCIDefineByPos(cursor,&pOciDefine, pOciError,2,&id,sizeof(int),
SQLT_INT,pIndicator, 0, 0,OCI_DEFAULT);
answer = OCIDefineByPos(cursor,&pOciDefine2, pOciError,1,ename,40,
SQLT_STR,pIndicator3, 0, 0,OCI_DEFAULT);
if (answer == 0)
while ((answer = OCIStmtFetch(cursor,pOciError, 1,OCI_FETCH_NEXT,OCI_DEFAULT)) == 0)
{
printf("fetched id %d and name %s\n",id,ename);
}
answer = OCIHandleFree(pOciError, OCI_HTYPE_ERROR);
return 0;
}
And the following DBI perl example is thanks to q_richard_chen@yahoo.com (Richard Chen):
Hello Tom,
I was looking for such compilation of tips
on the topic. I did not find the section about doing
it using the popular perl DBI. After some fiddling I
get it working there too. Here is a complete working
example following your model using perl DBI. I think
it is a good idea that you include this in your howto
so that more people will benefit from it.
Thanks
Richard Chen
$ cat demo.pl
#!/usr/local/bin/perl -w
use strict;
use DBI;
use DBD::Oracle qw(:ora_types);
my $dbh = DBI->connect('dbi:Oracle:','scott','tiger') or die $DBI::errstr;
my $sth1 = $dbh->prepare(q{create or replace package types as
type cursorType is ref cursor;
end;});
$sth1->execute;
> >
$sth1 = $dbh->prepare(q{
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;});
$sth1->execute;
$sth1 = $dbh->prepare(q{
BEGIN
:cursor := sp_ListEmp;
END;
});
my $sth2;
$sth1->bind_param_inout(":cursor", \$sth2, 0, { ora_type => ORA_RSET } );
$sth1->execute();
while ( my @row = $sth2->fetchrow_array ) { print join("|",@row),"\n"; }
MFC + ODBC VERSION (example checked by Marcin Buchwald) marcin.buchwald@gazeta.pl Oracle server side code is just like in the VB example CDatabase m_DB;
BOOL ok = m_DB.OpenEx(_T("DSN=orcl;UID=velvet"),CDatabase::useCursorLib);
COraSet set(&m_DB);
set.m_Value = Text1.Text;
set.Open();
while (!set.IsEOF()) {
// set members contain values of single row
// use it here
set.MoveNext();
}
set.Close();
where
COraSet::COraSet(CDatabase* pdb) : CRecordset(pdb) {
m_nParams = 1;
m_nFields = ;
m_nDefaultType = snapshot;
}
CString COraSet::GetDefaultSQL() {
return _T("{call RefTest.GetEmpData(?,?)}");
}