For appeals, questions and feedback about Oracle Forums, please email oracle-forums-moderators_us@oracle.com. Technical questions should be asked in the appropriate category. Thank you!
VARIABLE threshold_value NUMBER; EXEC :threshold_value := 9; WITH got_running_totals AS ( SELECT output_date, quantity , SUM (quantity) OVER (ORDER BY output_date) AS running_total_quantity , ROW_NUMBER () OVER (ORDER BY output_date) AS cnt FROM outputs ) , got_rnk AS ( SELECT e.output_date AS start_date , l.output_date AS end_date , e.quantity + l.running_total_quantity - e.running_total_quantity AS total_quantity , 1 + l.cnt - e.cnt AS total_cnt , RANK () OVER (ORDER BY e.quantity + l.running_total_quantity - e.running_total_quantity DESC ) AS rnk FROM got_running_totals e -- e is earlier, l is later JOIN got_running_totals l ON e.cnt <= l.cnt AND e.quantity + l.running_total_quantity - e.running_total_quantity < :threshold_value ) SELECT start_date , end_date , total_quantity , total_cnt FROM got_rnk WHERE rnk = 1 ;
... , RANK () OVER (ORDER BY l.output_date - e.output_date DESC ) AS rnk
threshold '14' would give: 31-JUL-3000 14.00.00, 31-JUL-3000 22.00.00, 13, 4
31-JUL-3000 14.00.00, 01-AUG-3000 02.00.00, 13, 4
with t(output_date,quantity) as( select to_date('31-07-3000 09.00.00','DD-MM-YYYY HH24.MI.SS'), 10 from dual union select to_date('31-07-3000 12.00.00','DD-MM-YYYY HH24.MI.SS'),100 from dual union select to_date('31-07-3000 14.00.00','DD-MM-YYYY HH24.MI.SS'), 1 from dual union select to_date('31-07-3000 18.00.00','DD-MM-YYYY HH24.MI.SS'), 1 from dual union select to_date('31-07-3000 20.30.00','DD-MM-YYYY HH24.MI.SS'), 1 from dual union select to_date('31-07-3000 22.00.00','DD-MM-YYYY HH24.MI.SS'), 10 from dual union select to_date('01-08-3000 02.00.00','DD-MM-YYYY HH24.MI.SS'), 10 from dual), tmp(output_date,quantity,rn) as( select output_date,quantity, Row_Number() over(order by output_date) from t), rec(rootOutput_date,output_date,rn,sumVal,cnt) as( select output_date,output_date,rn,quantity,1 from tmp where quantity < 9 /*threshold*/ union all select a.rootOutput_date,b.output_date,b.rn, a.sumVal+b.quantity,a.cnt+1 from rec a,tmp b where a.rn+1=b.rn and a.sumVal+b.quantity < 9 /*threshold*/) select to_char(rootOutput_date,'YYYY/MM/DD HH24:MI') as rootOutput_date, to_char(output_date,'YYYY/MM/DD HH24:MI') as output_date,sumVal,cnt from (select rootOutput_date,output_date,sumVal,cnt, max(sumVal) over() as maxSumVal from rec) where sumVal = maxSumVal; rootOutput_date output_date sumVal cnt ---------------- ---------------- ------ --- 3000/07/31 14:00 3000/07/31 20:30 3 3
with t(output_date,quantity) as( select to_date('31-07-3000 09.00.00','DD-MM-YYYY HH24.MI.SS'), 10 from dual union select to_date('31-07-3000 12.00.00','DD-MM-YYYY HH24.MI.SS'),100 from dual union select to_date('31-07-3000 14.00.00','DD-MM-YYYY HH24.MI.SS'), 1 from dual union select to_date('31-07-3000 18.00.00','DD-MM-YYYY HH24.MI.SS'), 1 from dual union select to_date('31-07-3000 20.30.00','DD-MM-YYYY HH24.MI.SS'), 1 from dual union select to_date('31-07-3000 22.00.00','DD-MM-YYYY HH24.MI.SS'), 10 from dual union select to_date('01-08-3000 02.00.00','DD-MM-YYYY HH24.MI.SS'), 10 from dual) select to_char(staD,'YYYY/MM/DD HH24:MI') as staD, to_char(endD,'YYYY/MM/DD HH24:MI') as endD,sumVal,cnt from (select a.output_date as staD,b.output_date as endD, sum(c.quantity) as sumVal,count(*) as cnt, max(sum(c.quantity)) over() as maxSumVal from t a,t b,t c where a.output_date < b.output_date and c.output_date between a.output_date and b.output_date group by a.output_date,b.output_date having sum(c.quantity) < 9 /*threshold*/) where sumVal = maxSumVal; staD endD sumVal cnt ---------------- ---------------- ------ --- 3000/07/31 14:00 3000/07/31 20:30 3 3
WITH got_running_totals AS ( SELECT output_date, quantity , SUM (quantity) OVER (ORDER BY output_date) AS running_total_quantity , ROW_NUMBER () OVER (ORDER BY output_date) AS cnt FROM outputs ) , got_rnk AS ( SELECT e.output_date AS start_date , l.output_date AS end_date , ( l.running_total_quantity -- Changed - e.running_total_quantity ) - l.quantity AS total_quantity , ( 1 + l.cnt -- Changed - e.cnt ) - 2 AS total_cnt , RANK () OVER (ORDER BY l.output_date - e.output_date DESC ) AS rnk FROM got_running_totals e -- e is earlier, l is later JOIN got_running_totals l ON e.cnt < l.cnt -- Changed AND ( l.running_total_quantity -- Changed - e.running_total_quantity ) - l.quantity <= :threshold_value ) SELECT start_date , end_date , total_quantity , total_cnt , (end_date - start_date) * 24 AS timespan_hours -- Added FROM got_rnk WHERE rnk = 1 ;
` TOTAL_ TOTAL TIMESPAN START_DATE END_DATE QUANTITY _CNT _HOURS -------------------- -------------------- -------- ----- -------- 31-JUL-3000 12.00.00 31-JUL-3000 22.00.00 3 3 10
TOTAL_ TOTAL MAX_GAP START_DATE END_DATE QUANTITY _CNT _HOURS -------------------- -------------------- -------- ----- -------- 31-JUL-3000 12.00.00 31-JUL-3000 22.00.00 3 3 4
WITH got_running_totals AS ( SELECT output_date, quantity, SUM (quantity) OVER (ORDER BY output_date) AS running_total_quantity, ROW_NUMBER () OVER (ORDER BY output_date) AS cnt, (LEAD (output_date) OVER (ORDER BY output_date) - output_date) * 24 AS hours_to_next_output FROM outputs ) --select * from got_running_totals; , got_rnk AS ( SELECT e.output_date AS start_date, l.output_date AS end_date, e.quantity + l.running_total_quantity - e.running_total_quantity AS total_quantity, 1 + l.cnt - e.cnt AS total_cnt, RANK () OVER (ORDER BY e.quantity + l.running_total_quantity - e.running_total_quantity DESC) AS rnk, MAX (e.hours_to_next_output) OVER (ORDER BY e.quantity + l.running_total_quantity - e.running_total_quantity DESC) AS largest_gap FROM got_running_totals e -- e is earlier, l is later JOIN got_running_totals l ON e.cnt <= l.cnt AND e.quantity + l.running_total_quantity - e.running_total_quantity < :threshold_value ) --select * from got_rnk; SELECT start_date , end_date , total_quantity , total_cnt , largest_gap FROM got_rnk WHERE rnk = 1 ;
with t(output_date,quantity) as( select to_date('31-07-3000 09.00.00','DD-MM-YYYY HH24.MI.SS'), 10 from dual union select to_date('31-07-3000 12.00.00','DD-MM-YYYY HH24.MI.SS'),100 from dual union select to_date('31-07-3000 14.00.00','DD-MM-YYYY HH24.MI.SS'), 1 from dual union select to_date('31-07-3000 18.00.00','DD-MM-YYYY HH24.MI.SS'), 1 from dual union select to_date('31-07-3000 20.30.00','DD-MM-YYYY HH24.MI.SS'), 1 from dual union select to_date('31-07-3000 22.00.00','DD-MM-YYYY HH24.MI.SS'), 10 from dual union select to_date('01-08-3000 02.00.00','DD-MM-YYYY HH24.MI.SS'), 10 from dual), tmp(output_date,quantity,rn) as( select output_date,quantity, Row_Number() over(order by output_date) from t), rec(rootOutput_date,output_date,rn,sumVal,cnt,maxDiff) as( select output_date,output_date,rn,quantity,1,0 from tmp where quantity < 9 /*threshold*/ union all select a.rootOutput_date,b.output_date,b.rn, a.sumVal+b.quantity,a.cnt+1, greatest(a.maxDiff,(b.output_date-a.output_date)*24) from rec a,tmp b where a.rn+1=b.rn and a.sumVal+b.quantity < 9 /*threshold*/) select to_char(rootOutput_date,'YYYY/MM/DD HH24:MI') as rootOutput_date, to_char(output_date,'YYYY/MM/DD HH24:MI') as output_date,sumVal,cnt,maxDiff from (select rootOutput_date,output_date,sumVal,cnt,maxDiff, max(sumVal) over() as maxSumVal from rec) where sumVal = maxSumVal; rootOutput_date output_date sumVal cnt maxDiff ---------------- ---------------- ------ --- ------- 3000/07/31 14:00 3000/07/31 20:30 3 3 4