Skip to Main Content

Breadcrumb

Question and Answer

Chris Saxon

Thanks for the question, Henry.

Asked: June 08, 2016 - 5:59 pm UTC

Last updated: June 10, 2016 - 2:57 am UTC

Version: Oracle Sql Developer Version 3.2.20.09

Viewed 1000+ times

You Asked

I am trying to create a function right now (instead of a package) that selects the column data that is currently inside of my OP_GUIDE_VIEW and OPGUIDE_DEFAULTS_VIEW.

Just need a function that selects what's there. Not modifying anything, don't think I need parameters or anything either. I have tried something similar to the following but I can't figure it out: What I have right now (Error in it, but that's my current process atleast):

CREATE OR REPLACE 
PACKAGE PKG_OPGUIDE_COLLECTIONDATA AS 

FUNCTION fn_view RETURN VARCHAR2 
As v_fn_view Varchar2
Begin
SELECT CATEGORY, SUB_CATEGORY, JOB_DESC, COMMENTS, JOB_NAME, COMBINEDCATEGORY, SUBJECT_MAIN_DOC_INPUT, CONTACT_MAIN_DOC_INPUT, OPGUIDENAME_MAIN_DOC_INPUT, ATTACHMENTS, OPGUIDE_COLLECTIONS_ID, START_DATE, END_DATE
FROM OPGUIDE_DEFAULTS_VIEW, OP_GUIDE_VIEW;

RETURN v_fn_view;
END fn_view;

END;


OPGUIDE_VIEW:
SELECT OPGUIDE_COLLECTIONS_ID,
    CATEGORY,
    START_DATE,
    END_DATE,
    SUB_CATEGORY,
    JOB_DESC,
    COMMENTS,
    JOB_NAME,
    ATTACHMENTS,
    CATEGORY
    ||' - '
    || SUB_CATEGORY CombinedCategory,
    (
    CASE
      WHEN SCHEDULE IS NULL
      THEN 'Schedule not declared.'
      ELSE SCHEDULE
    END) AS SCHEDULE
  FROM OPGUIDE_COLLECTIONS
  WHERE END_DATE >= SYSDATE
  AND START_DATE <= SYSDATE;



OPGUIDE_DEFAULTS_VIEW:

SELECT SUBJECT_MAIN_DOC_INPUT,
    CONTACT_MAIN_DOC_INPUT,
    OPGUIDENAME_MAIN_DOC_INPUT
  FROM OPGUIDE_DEFAULTS;


Image of the datatypes if needed.
http://i.stack.imgur.com/NdjlV.png

and Connor said...

OK, we need to talk about the concept of a "resultset". Any query you run will typically return:

1- a single value (eg "select name from emp where primary_key_col = 123")
2- multiple values (eg "select name from emp")
3- multiple rows (eg "select * from emp")

So for each, you need something for that query to return the results *into*, or some means for passing those values back to the calling environment.

So for something like (1), your function is close, eg

function F return number
  return_val number
begin
  select simple_val into return_val from my_table 
  where primary_key_col = 123;

  return return_val;
end;


But obviously a single return_val wont cut it if you want to return multiple values etc etc.

In your case, I'm guessing you want to return the contents of the view back to the calling environment. In that case, you *probably* want to use a REF CURSOR. Rather than sending back all the data, it will pass back a pointer (or handle) via which the calling environment can get the data.

eg

SQL> create or replace
  2  function F return sys_refcursor is
  3    rc sys_refcursor;
  4  begin
  5    open rc for
  6      select * from scott.emp;
  7
  8    return rc;
  9  end;
 10  /

Function created.


So the function wont return *data*, it returns a pointer to the data. Your client software provides a local pointer to that data. For example, in SQL Plus I declare a local ref cursor, and then "attach" it to the function

SQL> variable rc refcursor
SQL> exec :rc := f;

PL/SQL procedure successfully completed.


At this point, the data has not yet been fetched. But when I ask SQL Plus to "print" out the local variable, I will then do the fetching

SQL> print rc

     EMPNO ENAME      JOB              MGR HIREDATE         SAL       COMM     DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
      7369 SMITH      CLERK           7902 17-DEC-80        800                    20
      7499 ALLEN      SALESMAN        7698 20-FEB-81       1600        300         30
      7521 WARD       SALESMAN        7698 22-FEB-81       1250        500         30
      7566 JONES      MANAGER         7839 02-APR-81       2975                    20
      7654 MARTIN     SALESMAN        7698 28-SEP-81       1250       1400         30
      7698 BLAKE      MANAGER         7839 01-MAY-81       2850                    30
      7782 CLARK      MANAGER         7839 09-JUN-81       2450                    10
      7788 SCOTT      ANALYST         7566 09-DEC-82       3000                    20
      7839 KING       PRESIDENT            17-NOV-81       5000                    10
      7844 TURNER     SALESMAN        7698 08-SEP-81       1500                    30
      7876 ADAMS      CLERK           7788 12-JAN-83       1100                    20
      7900 JAMES      CLERK           7698 03-DEC-81        950                    30
      7902 FORD       ANALYST         7566 03-DEC-81       3000                    20
      7934 MILLER     CLERK           7782 23-JAN-82       1300                    10

14 rows selected.


Whether you are using Java, Python, .Net etc...All of these have similar facilities for fetching from a ref cursor.

Hope this helps.

PS - use SQL Dev 4 :-)

Rating

  (1 rating)

Is this answer out of date? If it is, please let us know via a Comment

Comments

Henry, June 09, 2016 - 3:20 pm UTC

Ok, so I'm trying to switch to a REF cursor type deal that you've suggested, right now, I've got the following:

create or replace 
PACKAGE PKG_OPGUIDE_COLLECTIONDATA AS

type v_cursor is ref cursor
return OPGUIDE_VIEW%rowtype;
 c2 v_cursor;
 r_c2 c2%rowtype;

 function fn_opview return v_cursor 
 is c1 v_cursor;
 begin
 open c1 for select * from OPGUIDE_VIEW;
 return c1;
 end;

 begin
 c2 := fn_opview;
 loop
 fetch c2 into r_c2;
 exit when c2%notfound;
 dbms_output.put_line(initcap(r_c2.JOB_NAME));
 end loop;
 close c2;
 end;

END PKG_OPGUIDE_COLLECTIONDATA;


However, I've got an error that I just can't seem to figure out.

PLS-00103: Encountered the symbol "IS" when expecting one of the following:

   constant exception <an identifier>
   <a double-quoted delimited-identifier> table long double ref
   char time timestamp interval date binary national character
   nchar


From what I can see, should be relatively correct, perhaps I'm messing up the Syntax?
Chris Saxon
June 10, 2016 - 2:57 am UTC

Package have a public and a private component.

Here's a demo

SQL> create or replace
  2  PACKAGE PKG_OPGUIDE_COLLECTIONDATA AS
  3
  4   type v_cursor is ref cursor return scott.emp%rowtype;
  5
  6   function fn_opview return v_cursor;
  7   procedure output_the_data;
  8
  9  END PKG_OPGUIDE_COLLECTIONDATA;
 10  /

Package created.

SQL>
SQL> create or replace
  2  PACKAGE BODY PKG_OPGUIDE_COLLECTIONDATA AS
  3
  4   function fn_opview return v_cursor is
  5     c1 v_cursor;
  6   begin
  7     open c1 for select * from scott.emp;
  8     return c1;
  9   end;
 10
 11   procedure output_the_data is
 12     c2 v_cursor;
 13     r_c2 scott.emp%rowtype;
 14   begin
 15     c2 := fn_opview;
 16     loop
 17       fetch c2 into r_c2;
 18       exit when c2%notfound;
 19       dbms_output.put_line(initcap(r_c2.ename));
 20     end loop;
 21     close c2;
 22   end;
 23
 24  END PKG_OPGUIDE_COLLECTIONDATA;
 25  /

Package body created.

SQL> sho err
No errors.
SQL>
SQL> set serverout on
SQL> exec PKG_OPGUIDE_COLLECTIONDATA.output_the_data;
Smith
Allen
Ward
Jones
Martin
Blake
Clark
Scott
King
Turner
Adams
James
Ford
Miller

PL/SQL procedure successfully completed.



But I'd strongly encourage you to have a good read of the plsql docs to get yourself up to speed

http://docs.oracle.com/database/121/LNPLS/toc.htm


More to Explore

PL/SQL demos

Check out more PL/SQL tutorials on our LiveSQL tool.

PL/SQL docs

PL/SQL reference manual from the Oracle documentation library