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
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 :-)