Example: Returning a REF CURSOR from a procedure (PL/SQL)
This example demonstrates how to define and open a REF CURSOR variable, and then pass it as a procedure parameter.
The cursor variable is specified as an IN OUT parameter so that
the result set is made available to the caller of the procedure:
CREATE OR REPLACE PROCEDURE emp_by_job (
p_job VARCHAR2,
p_emp_refcur IN OUT SYS_REFCURSOR
)
IS
BEGIN
OPEN p_emp_refcur FOR SELECT empno, ename FROM emp WHERE job = p_job;
END;
The EMP_BY_JOB procedure is invoked in the following
anonymous block by assigning the procedure's IN OUT parameter
to a cursor variable that was declared in the anonymous block's
declaration section. The result set is fetched using this cursor variable. DECLARE
v_empno emp.empno%TYPE;
v_ename emp.ename%TYPE;
v_job emp.job%TYPE := 'SALESMAN';
v_emp_refcur SYS_REFCURSOR;
BEGIN
DBMS_OUTPUT.PUT_LINE('EMPLOYEES WITH JOB ' || v_job);
DBMS_OUTPUT.PUT_LINE('EMPNO ENAME');
DBMS_OUTPUT.PUT_LINE('----- -------');
emp_by_job(v_job, v_emp_refcur);
LOOP
FETCH v_emp_refcur INTO v_empno, v_ename;
EXIT WHEN v_emp_refcur%NOTFOUND;
DBMS_OUTPUT.PUT_LINE(v_empno || ' ' || v_ename);
END LOOP;
CLOSE v_emp_refcur;
END;
The following example output is generated when the
anonymous block executes:EMPLOYEES WITH JOB SALESMAN
EMPNO ENAME
----- -------
7499 ALLEN
7521 WARD
7654 MARTIN
7844 TURNER