Skip to Main Content
  • Questions
  • ORA-01001: invalid cursor while using function returning ref cursor.

Breadcrumb

Question and Answer

Chris Saxon

Thanks for the question, Mohini.

Asked: July 26, 2017 - 11:06 am UTC

Last updated: August 29, 2017 - 10:28 am UTC

Version: 11g

Viewed 10K+ times! This question is

You Asked

Hi Team,

I am getting these errors 
(1 - ORA-00932: inconsistent datatypes: expected - got -

 2 - <b>ORA-01001: invalid cursor</b>) 
 
when I am using function returning ref cursor.
Can anyone help me in this.

These are the efforts which I have taken to implement this.

1. I have created a function returning refcursor.


create or replace function "FUNC_ALLOCATION_DASHBOARD"(start_date in DATE, end_date in DATE) return SYS_REFCURSOR
IS
l_ret_rc SYS_REFCURSOR;
ss_interval number;
dayInterval number; 
ss_qry varchar2(20000); 
ss_qry_main varchar2(1000);
ss_qry_from varchar2(1000); 
ss_qry_where varchar2(1000);
ss_qry_groupBy varchar2(1000); 
ss_qry_build_alloc varchar2(20000); 
--ss_allocation_d varchar2(20000);
ss_dt date;
end_dt date;
v_startdate date;
total_days number;
cntr number;
BEGIN
 ss_qry_main := 'select ae.supervisorid,(select m.fname||'' ''||m.lname from resource m where m.srid = ae.supervisorid) "Manager",level,ae.srid,ae.fname||'' ''||ae.lname "Resource"';
 ss_qry_from := ' from detailstable ad, resource ae ';
 ss_qry_where := ' Where ae.ENDDATE IS NULL and ae.srid = ad.employeeid(+) start with ae.srid = (select aceemp.srid from resource aceemp where aceemp.fname||'' ''||aceemp.lname = ''Justin Todd'') connect by prior ae.srid = ae.supervisorid';
 ss_qry_groupBy := ' group by ae.supervisorid,level,ae.srid,ae.fname,ae.lname order by level';    
 cntr := 1;
 v_startdate := start_date;
 total_days := round((end_date - start_date)/7,0);
 for cntr in 1..total_days loop 
        --end_dt := ss_dt + 6;
        ss_qry_build_alloc := ss_qry_build_alloc ||', COALESCE(sum(case when ad.startdate <= '|| to_date(to_char(start_date, 'dd-mon-yyyy'),'dd-mon-yyyy') ||' and ad.enddate >= '|| to_date(to_char(end_date, 'dd-mon-yyyy'),'dd-mon-yyyy') ||'then round(ad.weeklyallocpercent*100,0) end),0) '||' "Wk-'|| to_char(to_date(v_startdate, 'MM/DD/YYYY'),'WW') ||'"';
        v_startdate := v_startdate + 6;
        end loop;
     ss_qry := ss_qry_main||ss_qry_build_alloc||ss_qry_from||ss_qry_where||ss_qry_groupBy;
    --return ss_qry;
    OPEN l_ret_rc FOR ss_qry; 
    return l_ret_rc;
   exception
       when others then
       dbms_output.put_line(sqlerrm);
       return null;
end FUNC_ALLOCATION_DASHBOARD;

2. Created table of object type.

CREATE OR REPLACE TYPE  "ALLOCATION_TYPE" as OBJECT
(
  supervisorid number
  , mgr varchar2(100)
  , hlevel number
  , srid number
  , employee varchar2(100)
  , week1 number
  , week2 number
  , week3 number
  , week4 number
  , week5 number
  , week6 number
  , week7 number
  , week8 number
  , week9 number
  , week10 number
  , week11 number
  , week12 number
  , week13 number
  , week14 number
  , week15 number
  , week16 number
  , week17 number
  , week18 number
  , week19 number
  , week20 number
  , week21 number
  , week22 number
  , week23 number
  , week24 number
  , week25 number
  , week26 number
  , week27 number
  , week28 number
  , week29 number
  , week30 number
  , week31 number
  , week32 number
  , week33 number
  , week34 number
  , week35 number
  , week36 number
  , week37 number
  , week38 number
  , week39 number
  , week40 number
  , week41 number
  , week42 number
  , week43 number
  , week44 number
  , week45 number
  , week46 number
  , week47 number
  , week48 number
  , week49 number
  , week50 number
  , week51 number
  , week52 number
  , week53 number
)
/

3. CREATE OR REPLACE TYPE  "ALLOCATION_TAB_TYPE" IS TABLE OF allocation_type
/

4. Created a pipelined function

create or replace FUNCTION allocation_dashboard_pipe_fn( i_cursor SYS_REFCURSOR)
    RETURN allocation_tab_type PIPELINED IS
    l_row allocation_type := allocation_type(NULL, NULL, NULL, NULL, NULL, NULL, NULL,null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null, null);
BEGIN
    LOOP
        FETCH i_cursor INTO l_row.supervisorid, l_row.mgr, l_row.hlevel, l_row.srid, l_row.employee, l_row.week1, l_row.week2, l_row.week3, l_row.week4, l_row.week5,l_row.week6, l_row.week7, l_row.week8, l_row.week9, l_row.week10, l_row.week11, l_row.week12, l_row.week13, l_row.week14, l_row.week15, l_row.week16, l_row.week17, l_row.week18, l_row.week19, l_row.week20, l_row.week21, l_row.week22, l_row.week23, l_row.week24, l_row.week25, l_row.week26, l_row.week27, l_row.week28, l_row.week29, l_row.week29, l_row.week30, l_row.week31, l_row.week32, l_row.week33, l_row.week34, l_row.week35, l_row.week36, l_row.week37, l_row.week38, l_row.week39, l_row.week40, l_row.week41, l_row.week42, l_row.week43,
l_row.week44, l_row.week45, l_row.week46, l_row.week47, l_row.week48, l_row.week49, l_row.week50, l_row.week51, l_row.week52, l_row.week53;
        EXIT WHEN i_cursor%NOTFOUND;
        PIPE ROW( l_row);
    END LOOP;
    CLOSE i_cursor;
    RETURN;
END;

5. Then call function in two ways 
  - SELECT * FROM TABLE(allocation_dashboard_pipe_fn(func_allocation_dashboard(to_date('01-jul-2017','dd-mon-yyyy'),to_date('31-jul-2017','dd-mon-yyyy'))));
      - Error no 2 Invalid cursor.

   
   Please help me I am not getting where I am doing wrong.

and Chris said...

Oh dear. You have:

   exception
       when others then
       dbms_output.put_line(sqlerrm);


In FUNC_ALLOCATION_DASHBOARD. "Something" is going wrong in the execution of this. Remove this exception handler to get a better idea of the error. Then debug this procedure on it's own to find out where the bug is.

Rating

  (14 ratings)

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

Comments

Mohini Jadhav, July 28, 2017 - 10:01 am UTC

Thank you Chris.

I will surely debug this and come back to you If I need any help.

I have one more query whether I am doing right process of using PIPELINED function and TYPE OBJECT?

Kindly give your some inputs on this.
Chris Saxon
July 28, 2017 - 10:24 am UTC

"I am doing right process of using PIPELINED function and TYPE OBJECT?"

What's your business requirement? Why alternatives did you consider and why did you reject them?

Mohini Jadhav, July 28, 2017 - 10:33 am UTC

My business need is- I want to show weekly report within two dates. The two dates can be a span of a month , a year etc.

I want to display this in apex interactive report.

I google it and then I found this methods, that we can use to show dynamic sql values in oracle.

My first function FUNC_ALLOCATION_DASHBOARD is returning dynamic sql query which I am going to use in pipelined function to display the data dynamically.

If you have any other easy way to do it. Please let me know. As I am working on this from long time.

Thanks in advance.




Chris Saxon
July 28, 2017 - 2:38 pm UTC

I'm not that familiar with APEX interactive reports. But can't you use your SQL directly in the report? Why do you need a pipelined table function?

Mohini Jadhav, July 28, 2017 - 5:57 pm UTC

I cannot use Dynamic sql in apex. For that reason I am using a pipelined function which I can use as a select function. I was trying to use function returning a query but unfortunately its not working.
Chris Saxon
July 31, 2017 - 10:23 am UTC

But why do you need dynamic SQL? Can't you use bind variables in your report?

For example, see:

https://apex.mt-ag.com/apex/f?p=136:15::::::

A reader, July 31, 2017 - 10:31 am UTC

I need dynamic sql because my number of columns will change depending upon the number of weeks between two date passed as a parameter. I am using dynamic sql becuase my column headers are not fixed. It is kind of weekly eport generating on the basis of two dates.

Variant

Racer I., July 31, 2017 - 12:37 pm UTC

Given that the current version is not really dynamic (always 53 weeks) what about this :

with
DateRange AS (
SELECT to_date('01-jul-2017','dd-mon-yyyy') dstart, to_date('31-jul-2017','dd-mon-yyyy') dend from dual),
AllData AS (
SELECT 'xxx' name, to_date('03-jul-2017','dd-mon-yyyy') ddate, 5 dvalue from dual union all
SELECT 'xxx' name, to_date('05-jul-2017','dd-mon-yyyy') ddate, 7 dvalue from dual union all
SELECT 'xxx' name, to_date('13-jul-2017','dd-mon-yyyy') ddate, 3 dvalue from dual union all
SELECT 'yyy' name, to_date('14-jul-2017','dd-mon-yyyy') ddate, 22 dvalue from dual union all
SELECT 'yyy' name, to_date('23-jul-2017','dd-mon-yyyy') ddate, 6 dvalue from dual union all
SELECT 'yyy' name, to_date('24-jul-2017','dd-mon-yyyy') ddate, 8 dvalue from dual),
ProcData AS(
select name, TO_NUMBER(TO_CHAR(ad.ddate, 'WW')) - TO_NUMBER(TO_CHAR(dr.dstart, 'WW')) Week, dvalue
from AllData ad
join DateRange dr ON (ad.ddate between dr.dstart and dr.dend))
select *
from ProcData
PIVOT (SUM(dvalue) FOR Week IN (1, 2, 3, 4, 5))

NAME 1 2 3 4 5
yyy 22 14
xxx 12 3

The list would have to be for the maximum weeks (53 assuming the date range cannot span more than a year).

Chris Saxon
July 31, 2017 - 4:33 pm UTC

Yep, seems to me something like that could work.

A reader, July 31, 2017 - 3:09 pm UTC

Hi,

Kindly bare with my questions as I am not able to understand the following block of code.
Can you please explain what exactly you have done in it.

AllData AS (
SELECT 'xxx' name, to_date('03-jul-2017','dd-mon-yyyy') ddate, 5 dvalue from dual union all
SELECT 'xxx' name, to_date('05-jul-2017','dd-mon-yyyy') ddate, 7 dvalue from dual union all
SELECT 'xxx' name, to_date('13-jul-2017','dd-mon-yyyy') ddate, 3 dvalue from dual union all
SELECT 'yyy' name, to_date('14-jul-2017','dd-mon-yyyy') ddate, 22 dvalue from dual union all
SELECT 'yyy' name, to_date('23-jul-2017','dd-mon-yyyy') ddate, 6 dvalue from dual union all
SELECT 'yyy' name, to_date('24-jul-2017','dd-mon-yyyy') ddate, 8 dvalue from dual),
Chris Saxon
July 31, 2017 - 4:34 pm UTC

That's just a way of generating some sample data. The idea is you put your query in that section.

A reader, August 01, 2017 - 8:43 am UTC

It's awsome!! Working as I expected. Can we do the week number dynamic instead of passing static for week IN (1, 2, 3, 4, 5)?

I mean, is it possible to calculate number of weeks within two dates and then pass this number to for as week number?
Chris Saxon
August 01, 2017 - 2:00 pm UTC

You mean in the pivot clause (PIVOT (SUM(dvalue) FOR Week IN (1, 2, 3, 4, 5))?

You have to use dynamic SQL if you want to change the elements in here. But why not always pivot 53 values then only select the ones you want?

Variant II

Racer I., August 01, 2017 - 11:35 am UTC

with
DateRange AS (
SELECT to_date('01-jul-2017','dd-mon-yyyy') dstart, to_date('31-jul-2017','dd-mon-yyyy') dend from dual),
AllData AS (
SELECT 'xxx' name, to_date('03-jul-2017','dd-mon-yyyy') ddate, 5 dvalue from dual union all
SELECT 'xxx' name, to_date('05-jul-2017','dd-mon-yyyy') ddate, 7 dvalue from dual union all
SELECT 'xxx' name, to_date('13-jul-2017','dd-mon-yyyy') ddate, 3 dvalue from dual union all
SELECT 'yyy' name, to_date('14-jul-2017','dd-mon-yyyy') ddate, 22 dvalue from dual union all
SELECT 'yyy' name, to_date('23-jul-2017','dd-mon-yyyy') ddate, 6 dvalue from dual union all
SELECT 'yyy' name, to_date('24-jul-2017','dd-mon-yyyy') ddate, 8 dvalue from dual),
ProcData AS(
select name, TO_NUMBER(TO_CHAR(ad.ddate, 'WW')) Week, dvalue
from AllData ad
join DateRange dr ON (ad.ddate between dr.dstart and dr.dend))
select *
from ProcData
PIVOT (SUM(dvalue) FOR Week IN (1 as Wk1, 2 as Wk2, 26 as Wk26, 27 as Wk27, 28 as Wk28, 29 As Wk29, 30 As Wk30, 31 As Wk31, 52 as Wk52, 53 as Wk53))

NAME WK1 WK2 WK26 WK27 WK28 WK29 WK30 WK31 WK52 WK53
yyy 22 14
xxx 12 3

That would give actual column names (and unlike the previous version should also work across new year, when week numbers would have become negative and not shown up).
Pivot is not dynamic, so you can't adjust the weeks to just the ones in the date range.
I would try to look into what APEX actually does with the result. Does it use the columnnames of the SQL or does it supply its own? If the latter maybe they can be programmatically adjusted based on the date range? Then the previous version would suffice with this

TRUNC((ad.ddate - dr.dstart) / 7) + 1 Week

to avoid negative week numbers.


A reader, August 02, 2017 - 10:43 am UTC

- It is throwing error when I am trying the following code
with
DateRange AS (
SELECT to_date('01-jul-2017','dd-mon-yyyy') dstart, to_date('31-jul-2017','dd-mon-yyyy') dend from dual),
AllData AS (
select ae.supervisorid,(select m.fname||' '||m.lname from ace_employees m where m.srid = ae.supervisorid) "Manager",level,ae.srid,ae.fname||' '||ae.lname "Resource",to_date(ad.startdate,'mm/dd/yyyy') ddate, sum(round(ad.weeklyallocpercent*100,0)) dvalue
from allocationdetails ad, ACE_EMPLOYEES ae Where ae.ENDDATE IS NULL and ae.srid = ad.employeeid(+) start with ae.srid = (select aceemp.srid from ace_employees aceemp where aceemp.fname||' '||aceemp.lname = 'Swetha Justin') connect by prior ae.srid = ae.supervisorid
group by ae.supervisorid,level,ae.srid,ae.fname,ae.lname,ad.startdate,ad.weeklyallocpercent order by level),
ProcData AS(
select supervisorid, Manager, level, srid, Resource, TRUNC((ad.ddate - dr.dstart) / 7) + 1 Week, dvalue
from AllData adt
join DateRange dr ON (adt.ddate between dr.dstart and dr.dend))

PIVOT (SUM(dvalue) FOR Week IN (1 as Wk1, 2 as Wk2, 3 as Wk3, 4 as Wk4, 5 as Wk5, 6 as Wk6, 26 as Wk26, 27 as Wk27, 28 as Wk28, 29 As Wk29, 30 As Wk30, 31 As Wk31, 52 as Wk52, 53 as Wk53))


- In this what I am doing i want to sum the allocationpercent for each resource on weekly base. And why I want to make it dynamic because I have two different columns naming startdate and enddate. Hence i need to calculate the weekly allocation on passed dates.

- FYI in apex the columns names are based on columns fecth in sql query.

My date passing will be dynamic.


Chris Saxon
August 02, 2017 - 3:39 pm UTC

You're not selecting from any of the queries you define in the with clause! You need to do this in your main select.

"In this what I am doing i want to sum the allocationpercent for each resource on weekly base. And why I want to make it dynamic because I have two different columns naming startdate and enddate. Hence i need to calculate the weekly allocation on passed dates."

I'm not following. Can you be more specific and provide examples?

A reader, August 02, 2017 - 5:46 pm UTC

Hi,
My use case for this implementation is.
1. I will allow users to pass two dates StartDate and EndDate, by default it would be current month's 1st date and last date.
2. So it will calculate number of weeks from given dates Ex: for month of august it would be week31 - week34.
3. Following is my normal select statement which I can use for populating this data.

select
ae.supervisorid,
(select m.fname||' '||m.lname from ace_employees m where m.srid = ae.supervisorid) "Manager",
level,
ae.srid,
ae.fname||' '||ae.lname "Resource",
COALESCE(sum(case when ad.startdate <= '30-jul-2017' and ad.enddate >= '06-aug-2017' then round(ad.weeklyallocpercent*100,0) end),0) "Wk-31",
COALESCE(sum(case when ad.startdate <= '06-aug-2017' and ad.enddate >= '13-aug-2017' then round(ad.weeklyallocpercent*100,0) end),0) "Wk-32",
COALESCE(sum(case when ad.startdate <= '13-aug-2017' and ad.enddate >= '20-aug-2017' then round(ad.weeklyallocpercent*100,0) end),0) "Wk-33",
COALESCE(sum(case when ad.startdate <= '20-aug-2017' and ad.enddate >= '27-aug-2017' then round(ad.weeklyallocpercent*100,0) end),0) "Wk-34",
COALESCE(sum(case when ad.startdate <= '27-aug-2017' and ad.enddate >= '03-sep-2017' then round(ad.weeklyallocpercent*100,0) end),0) "Wk-35"
from
allocationdetails ad, ACE_EMPLOYEES ae
Where
ae.ENDDATE IS NULL
and ae.srid = ad.employeeid(+) start with ae.srid = (select aceemp.srid from ace_employees aceemp where aceemp.fname||' '||aceemp.lname = 'Manu Ramakrishnan') connect by prior ae.srid = ae.supervisorid
group by
ae.supervisorid,
level,
ae.srid,
ae.fname,
ae.lname
order by
ae.fname

4. I want to make this dynamic depending upon the dates passed by user.
5. This is my actual create statement for allocationdetails table and employees table.

a- CREATE TABLE "ALLOCATIONDETAILS"
( "ALLOCID" NUMBER NOT NULL ENABLE,
"WEEKLYALLOCPERCENT" NUMBER(2,2) NOT NULL ENABLE,
"EMPLOYEEID" NUMBER,
"STARTDATE" DATE NOT NULL ENABLE,
"ENDDATE" DATE NOT NULL ENABLE,
"SUPERVISORID" NUMBER,
CONSTRAINT "ALLOCATIONDETAILS_PK" PRIMARY KEY ("ALLOCID") ENABLE
)
/

b- CREATE TABLE "ACE_EMPLOYEES"
( "SRID" NUMBER NOT NULL ENABLE,
"FNAME" VARCHAR2(50) NOT NULL ENABLE,
"LNAME" VARCHAR2(100) NOT NULL ENABLE,
"DateofJoining" DATE NOT NULL ENABLE,
"Inactive" DATE,
"SUPERVISORID" NUMBER,
CONSTRAINT "ACE_EMPLOYEES_PK" PRIMARY KEY ("SRID") ENABLE
)
/

5. O/p
Employee Manager w31 w32 w33 w34
Tam Scott 50 40 30 50
James Dan 34 56 67 80

Kindly check this and let me know if required anything.
I have tried different possible ways to achieve this but could not able to do it. I am asking this to you because at some extent your answer fulfill my requirement.
Thanks in advance.
Chris Saxon
August 03, 2017 - 9:53 am UTC

It's not exactly pretty, but you could to_char the dates using WW (week numbers starting 1 Jan) or IW (ISO week numbers). Then write that condition for all 53 weeks.

with rws as (
  select rownum id, 
         date'2016-01-01'+(rownum-1)*7 stdt,
         date'2016-01-01'+rownum*7 endt 
  from   dual
  connect by level <= 5
)
  select to_char(stdt, 'ww'), to_char(endt, 'ww'),
         case when to_char(stdt, 'ww') <= 1 and to_char(endt, 'ww') > 1 then id end wk1,
         case when to_char(stdt, 'ww') <= 2 and to_char(endt, 'ww') > 2 then id end wk2,
         case when to_char(stdt, 'ww') <= 3 and to_char(endt, 'ww') > 3 then id end wk3,
         case when to_char(stdt, 'ww') <= 4 and to_char(endt, 'ww') > 4 then id end wk4
  from   rws;

TO TO        WK1        WK2        WK3        WK4
-- -- ---------- ---------- ---------- ----------
01 02          1                                 
02 03                     2                      
03 04                                3           
04 05                                           4
05 06                                            


Or you could go adapt the pivot solution Racer posted.

Mohini Jadhav, August 23, 2017 - 8:12 pm UTC

Hi,
I have used this approach to achieve my goal and its working as expected but it is returning wrong number of weeklyallocpercent sum can you please help me in this.

My data stored in database is like this:
EMPLOYEEID STARTDATE ENDDATE WEEKLYALLOCPERCENT
17 2/21/2017 12/30/2018 0.05
17 2/15/2016 12/31/2017 0.05
17 2/28/2016 3/31/2018 0.05
17 11/30/2016 12/31/2017 0.05
17 3/13/2017 8/31/2017 0.1
17 9/12/2016 4/14/2021 0.05
17 2/20/2017 9/30/2017 0.05
17 10/20/2016 5/31/2018 0.05
17 10/20/2016 12/31/2017 0.05
17 1/25/2016 10/31/2020 0.05
17 5/13/2016 9/30/2017 0.05
17 2/28/2016 12/31/2017 0.08
17 2/1/2016 12/15/2017 0.05
17 1/25/2016 12/31/2017 0.08
Total = 81%

1. When I am executing below query to display weekly report, it results the output as
:
select ae.fname||' '||ae.lname "Resource", (select m.fname||' '||m.lname from ace_employees m where m.srid = ae.supervisorid) "Manager", ae.srid, ae.supervisorid, level,
COALESCE(sum(case when '08/01/2017' between ad.startdate and ad.enddate then round(ad.weeklyallocpercent*100,0) end),0) "Aug-01",
COALESCE(sum(case when '08/08/2017' between ad.startdate and ad.enddate then round(ad.weeklyallocpercent*100,0) end),0) "Aug-08",
COALESCE(sum(case when '08/15/2017' between ad.startdate and ad.enddate then round(ad.weeklyallocpercent*100,0) end),0) "Aug-15",
COALESCE(sum(case when '08/22/2017' between ad.startdate and ad.enddate then round(ad.weeklyallocpercent*100,0) end),0) "Aug-22",
COALESCE(sum(case when '08/29/2017' between ad.startdate and ad.enddate then round(ad.weeklyallocpercent*100,0) end),0) "Aug-29",
COALESCE(sum(case when '09/05/2017' between ad.startdate and ad.enddate then round(ad.weeklyallocpercent*100,0) end),0) "Sep-05"
from
allocationdetails ad, ACE_EMPLOYEES ae
Where
ae.ENDDATE IS NULL
and ae.srid =17
and ae.srid = ad.employeeid(+) start with ae.srid = (select aceemp.srid from ace_employees aceemp where aceemp.supervisorid IS NULL) connect by prior ae.srid = ae.supervisorid
group by ae.supervisorid,level,ae.srid,ae.fname,ae.lname
order by 1 nulls last

OUTPUT:
Resource Manager Aug-01 Aug-08 Aug-15 Aug-22 Aug-29 Sep-05
17 James Bond 3078 3078 3078 3078 3078 3078

Idealy It should ahow the result as -
Resource Manager Aug-01 Aug-08 Aug-15 Aug-22 Aug-29 Sep-05
17 James Bond 81 81 81 81 81 81

Please help me on this, as this is found on production side.

Thanks in advance.
Chris Saxon
August 24, 2017 - 12:53 pm UTC

Can you give us the create table + insert into statements that will give us that output when we run your query?

Mohini Jadhav, August 24, 2017 - 2:03 pm UTC

SQL> create table ace_employees(srid number, fname varchar2(30), lname varchar2(30), supervisorid number, startdate date, enddate date);

Table created.

SQL> create table allocationdetails(allocid number, employeeid number, supervisorid number, startdate date, enddate date, weeklyallocpercent number);

Table created.

SQL> alter session set nls_date_format = 'dd/mm/yyyy';

Session altered.

SQL>
SQL> insert into ace_employees values(17,'Tom', 'Richard', '251', '01/03/2014', '');

1 row created.
SQL> insert into ace_employees values(18,'Jack', 'Will', '251', '01/03/2017', '');

1 row created.


SQL> insert into ace_employees values(251,'Moon', 'Lamba', '51', '01/03/2014', '');

1 row created.

SQL> commit;

Commit complete.

SQL> insert into allocationdetails values(1,'17','251','2/21/2017','12/30/2018','0.05');
1 row created.

SQL> insert into allocationdetails values(2,'17','251','2/28/2016','3/31/2018','0.05');
1 row created.

SQL> insert into allocationdetails values(3,'17','251','2/28/2016','3/31/2018','0.05');
1 row created.

SQL> insert into allocationdetails values(4,'17','251','11/30/2016','12/31/2017','0.05');
1 row created.

SQL> insert into allocationdetails values(5,'17','251','3/13/2017','8/31/2017','0.1');
1 row created.

SQL> insert into allocationdetails values(6,'17','251','9/12/2016','4/14/2021','0.05');
1 row created.

SQL> commit;

Commit complete.


- Now to generate weekly report I have written this function:

create or replace function "FUNC_ALLOCATION_DASHBOARD3"(p_start_date in date, p_end_date in date, p_manager_id in number := NULL, p_resource_id in NUMBER := NULL) return VARCHAR2
IS
l_qry varchar2(32000);
v_qry_main varchar2(1000);
v_qry_from varchar2(1000);
v_qry_where varchar2(1000);
v_qry_subwhere varchar2(1000);
v_qry_andCondn varchar2(1000);
v_qry_groupBy varchar2(1000);
v_qry_build_alloc varchar2(20000);
v_startdate date;
BEGIN
v_qry_main := 'select ae.fname||'' ''||ae.lname "Resource", (select m.fname||'' ''||m.lname from ace_employees m where m.srid = ae.supervisorid) "Manager", ae.srid, ae.supervisorid, level';
v_qry_from := ' from allocationdetails ad, ACE_EMPLOYEES ae ';
if p_manager_id is not null then
v_qry_subwhere := ' where aceemp.srid = '||p_manager_id;
else
v_qry_subwhere := ' where aceemp.supervisorid IS NULL';
end if;
if P_RESOURCE_id is not null then
v_qry_andCondn := ' and ae.srid ='||p_resource_id;
end if;
v_qry_where := ' Where ae.ENDDATE IS NULL '||v_qry_andCondn||' and ae.srid = ad.employeeid(+) start with ae.srid = (select aceemp.srid from ace_employees aceemp '||v_qry_subwhere||') connect by prior ae.srid = ae.supervisorid';
v_qry_groupBy := ' group by ae.supervisorid,level,ae.srid,ae.fname,ae.lname ';
for i in 0 .. (p_end_date - p_start_date)/7 + 1 loop
v_startdate := p_start_date+i*7;
v_qry_build_alloc := v_qry_build_alloc ||', COALESCE(sum(case when '''|| v_startdate ||''' between ad.startdate and ad.enddate then round(ad.weeklyallocpercent*100,0) end),0) '||'"'|| to_char(v_startdate,'Mon') ||'-'|| to_char(v_startdate,'DD') ||'"';
end loop;
l_qry := v_qry_main|| v_qry_build_alloc|| v_qry_from|| v_qry_where|| v_qry_groupBy;
return l_qry;
End FUNC_ALLOCATION_DASHBOARD3;

Which will return a below query:

select ae.fname||' '||ae.lname "Resource", (select m.fname||' '||m.lname from ace_employees m where m.srid = ae.supervisorid) "Manager", ae.srid, ae.supervisorid, level,
COALESCE(sum(case when '08/01/2017' between ad.startdate and ad.enddate then round(ad.weeklyallocpercent*100,0) end),0) "Aug-01",
COALESCE(sum(case when '08/08/2017' between ad.startdate and ad.enddate then round(ad.weeklyallocpercent*100,0) end),0) "Aug-08",
COALESCE(sum(case when '08/15/2017' between ad.startdate and ad.enddate then round(ad.weeklyallocpercent*100,0) end),0) "Aug-15",
COALESCE(sum(case when '08/22/2017' between ad.startdate and ad.enddate then round(ad.weeklyallocpercent*100,0) end),0) "Aug-22",
COALESCE(sum(case when '08/29/2017' between ad.startdate and ad.enddate then round(ad.weeklyallocpercent*100,0) end),0) "Aug-29",
COALESCE(sum(case when '09/05/2017' between ad.startdate and ad.enddate then round(ad.weeklyallocpercent*100,0) end),0) "Sep-05"
from
allocationdetails ad, ACE_EMPLOYEES ae
Where
ae.ENDDATE IS NULL
and ae.srid =17
and ae.srid = ad.employeeid(+) start with ae.srid = (select aceemp.srid from ace_employees aceemp where aceemp.supervisorid IS NULL) connect by prior ae.srid = ae.supervisorid
group by ae.supervisorid,level,ae.srid,ae.fname,ae.lname
order by 1
-------------------------------------------------------------
When I execute this query it is giving me following result which calculating wrong :

Resource Manager Aug-01 Aug-08 Aug-15 Aug-22 Aug-29 Sep-05
Tom Richard Moon Lamba 3078 3078 3078 3078 3078 3078

Kindly help me on this, I am not getting where I am doing wrong.

I found that the issue with my connect by query. It is summing up all the employees data for the respective Manager. I want to do it for individual Employeee under the respective Manager.

Thanks.
Chris Saxon
August 24, 2017 - 3:58 pm UTC

Why on earth have you got connect by prior in there?! What makes this a hierarchical query?

I'd start by getting rid of that...

Mohini Jadhav, August 24, 2017 - 4:01 pm UTC

I need to generate a weekly report on basis of hierarchy.

Is der any other way rather than connect by to achieve this?


Chris Saxon
August 24, 2017 - 4:57 pm UTC

I don't really understand what you're trying to do.

If you add more employees and managers, what should the output look like?

Give us the insert statements and what you want to see at the end.

Mohini Jadhav, August 24, 2017 - 5:13 pm UTC

SQL> insert into ace_employees values(19,'ttt', 'yyy', '251', '01/03/2014', '');

1 row created.
SQL> insert into ace_employees values(20,'Jack', 'Williams', '251', '01/03/2017', '');

1 row created.


SQL> insert into ace_employees values(251,'Moon', 'Lamba', '51', '01/03/2014', '');

1 row created.

SQL> commit;

Commit complete.

SQL> insert into allocationdetails values(7,'18','251','2/21/2017','12/30/2018','0.05');
1 row created.

SQL> insert into allocationdetails values(8,'18','251','2/28/2016','3/31/2018','0.05');
1 row created.

SQL> insert into allocationdetails values(9,'18','251','2/28/2016','3/31/2018','0.05');
1 row created.

SQL> insert into allocationdetails values(10,'18','251','11/30/2016','12/31/2017','0.05');
1 row created.

SQL> insert into allocationdetails values(11,'18','251','3/13/2017','8/31/2017','0.1');
1 row created.

SQL> insert into allocationdetails values(12,'18','251','9/12/2016','4/14/2021','0.05');
1 row created.

SQL> insert into allocationdetails values(13,'19','251','2/21/2017','12/30/2018','0.05');
1 row created.

SQL> insert into allocationdetails values(14,'19','251','2/28/2016','3/31/2018','0.05');
1 row created.

SQL> insert into allocationdetails values(15,'19','251','2/28/2016','3/31/2018','0.05');
1 row created.

SQL> insert into allocationdetails values(16,'19','251','11/30/2016','12/31/2017','0.05');
1 row created.

SQL> insert into allocationdetails values(17,'19','251','3/13/2017','8/31/2017','0.1');
1 row created.

SQL> insert into allocationdetails values(18,'19','251','9/12/2016','4/14/2021','0.05');
1 row created.

SQL> commit;

Now the OUtput should be
Resource Manager Aug-01 Aug-08 Aug-15 Aug-22 Aug-29 Sep-05
17 251 26 26 26 26 26 26
18 251 26 26 26 26 26 26
19 251 26 26 26 26 26 26
20 251 0 0 0 0 0 0

But it is giving
Resource Manager Aug-01 Aug-08 Aug-15 Aug-22 Aug-29 Sep-05
17 251 78 78 78 78 78 78
18 251 78 78 78 78 78 78
19 251 78 78 78 78 78 78
20 251 78 78 78 78 78 78

For all of them.
Pleas help me on this.
Thanks.
Chris Saxon
August 29, 2017 - 10:28 am UTC

So what? You want all the people who aren't managers? Why does that mean you need connect by?

Why specifically is this query not what you want?

delete allocationdetails;
delete ace_employees;
alter session set nls_date_format = 'mm/dd/yyyy';

insert into ace_employees values(17,'Tom', 'Richard', '251', '01/03/2014', ''); 
insert into ace_employees values(18,'Jack', 'Will', '251', '01/03/2017', ''); 
insert into ace_employees values(251,'Moon', 'Lamba', '51', '01/03/2014', ''); 
insert into ace_employees values(19,'ttt', 'yyy', '251', '01/03/2014', ''); 
insert into ace_employees values(20,'Jack', 'Williams', '251', '01/03/2017', ''); 

commit; 

insert into allocationdetails values(1,'17','251','2/21/2017','12/30/2018','0.05'); 
insert into allocationdetails values(2,'17','251','2/28/2016','3/31/2018','0.05'); 
insert into allocationdetails values(3,'17','251','2/28/2016','3/31/2018','0.05'); 
insert into allocationdetails values(4,'17','251','11/30/2016','12/31/2017','0.05'); 
insert into allocationdetails values(5,'17','251','3/13/2017','8/31/2017','0.1'); 
insert into allocationdetails values(6,'17','251','9/12/2016','4/14/2021','0.05'); 
insert into allocationdetails values(7,'18','251','2/21/2017','12/30/2018','0.05'); 
insert into allocationdetails values(8,'18','251','2/28/2016','3/31/2018','0.05');
insert into allocationdetails values(9,'18','251','2/28/2016','3/31/2018','0.05'); 
insert into allocationdetails values(10,'18','251','11/30/2016','12/31/2017','0.05'); 
insert into allocationdetails values(11,'18','251','3/13/2017','8/31/2017','0.1'); 
insert into allocationdetails values(12,'18','251','9/12/2016','4/14/2021','0.05'); 
insert into allocationdetails values(13,'19','251','2/21/2017','12/30/2018','0.05');
insert into allocationdetails values(14,'19','251','2/28/2016','3/31/2018','0.05'); 
insert into allocationdetails values(15,'19','251','2/28/2016','3/31/2018','0.05'); 
insert into allocationdetails values(16,'19','251','11/30/2016','12/31/2017','0.05'); 
insert into allocationdetails values(17,'19','251','3/13/2017','8/31/2017','0.1'); 
insert into allocationdetails values(18,'19','251','9/12/2016','4/14/2021','0.05'); 

select ae.fname||' '||ae.lname "Resource", 
(select m.fname||' '||m.lname from ace_employees m where m.srid = ae.supervisorid) "Manager", ae.srid, ae.supervisorid, 
COALESCE(sum(case when '08/01/2017' between ad.startdate and ad.enddate then round(ad.weeklyallocpercent*100,0) end),0) "Aug-01", 
COALESCE(sum(case when '08/08/2017' between ad.startdate and ad.enddate then round(ad.weeklyallocpercent*100,0) end),0) "Aug-08", 
COALESCE(sum(case when '08/15/2017' between ad.startdate and ad.enddate then round(ad.weeklyallocpercent*100,0) end),0) "Aug-15", 
COALESCE(sum(case when '08/22/2017' between ad.startdate and ad.enddate then round(ad.weeklyallocpercent*100,0) end),0) "Aug-22", 
COALESCE(sum(case when '08/29/2017' between ad.startdate and ad.enddate then round(ad.weeklyallocpercent*100,0) end),0) "Aug-29", 
COALESCE(sum(case when '09/05/2017' between ad.startdate and ad.enddate then round(ad.weeklyallocpercent*100,0) end),0) "Sep-05" 
from allocationdetails ad, ACE_EMPLOYEES ae 
Where ae.ENDDATE IS NULL 
and ae.srid = ad.employeeid(+) 
and  exists (
  select * from ACE_EMPLOYEES mgr
  where  ae.supervisorid = mgr.srid
)
group by ae.supervisorid,ae.srid,ae.fname,ae.lname 
order by 1 ;

Resource       Manager     SRID  SUPERVISORID  Aug-01  Aug-08  Aug-15  Aug-22  Aug-29  Sep-05  
Jack Will      Moon Lamba  18    251           35      35      35      35      35      25      
Jack Williams  Moon Lamba  20    251           0       0       0       0       0       0       
Tom Richard    Moon Lamba  17    251           35      35      35      35      35      25      
ttt yyy        Moon Lamba  19    251           35      35      35      35      35      25      

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