Skip to Main Content

SQL & PL/SQL

Announcement

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!

Getting quarters with two input date-parameters

748467Jan 22 2010 — edited Feb 8 2010
I have to find a way to get all the quarters between a startdate and an enddate, like 01-04-2009 (startdate) and 31-11-2009 (enddate). An extra condition is to count an extra quarter above the enddate, so the last quarter is 2010-01 (first quarter of 2010).

The desired result will be:

2009-02
2009-03
2009-04
2010-01

The start- and enddate are inputparameters.

How do I get this result?

Comments

6363
Here is an example
SQL> var start_date varchar2(10)
SQL> var end_date varchar2(10)
SQL> exec :start_date := '01/05/2010'; :end_date := '09/15/2010'

PL/SQL procedure successfully completed.

SQL> select
  2    trunc(add_months(to_date(:start_date,'MM/DD/YYYY'),3 * level),'Q')
  3  from
  4    dual
  5  connect by
  6    level <=
  7      (months_between(to_date(:end_date,'MM/DD/YYYY'),to_date(:start_date,'MM/DD/YYYY')) + 3) / 3;

TRUNC(ADD_
----------
04/01/2010
07/01/2010
10/01/2010

SQL>
http://download.oracle.com/docs/cd/E11882_01/server.112/e10592/functions218.htm#SQLRF06151
http://download.oracle.com/docs/cd/E11882_01/server.112/e10592/functions009.htm#SQLRF00603
http://download.oracle.com/docs/cd/E11882_01/server.112/e10592/functions100.htm#SQLRF00669
748467
This should almost do the trick, but now I have to count an extra quarter to the end date. The ordening of the result is also not correct:

select distinct to_char(qdate,'YYYYQ') quarter
from ( select add_months(to_date(:start_date,'DD/MM/YYYY'),m) qdate
from ( select level m
from dual
connect by level < ceil(months_between(to_date(:end_date,'DD/MM/YYYY'),to_date(:start_date,'DD/MM/YYYY')))
)
) order by quarter

So the result is:

20092
20093
20094

Anyone who knows how to add an extra quarter?

Edited by: user12493601 on 22-jan-2010 14:52
fsitja
Just add 3 months I guess:
SQL> SELECT DISTINCT to_char(qdate, 'YYYY') || '-Q' || to_char(qdate, 'Q') quarter
  2    FROM (SELECT add_months(to_date('01/04/2009', 'DD/MM/YYYY'), m) qdate
  3            FROM (SELECT LEVEL m
  4                    FROM dual
  5                  CONNECT BY LEVEL - 3 < ceil(months_between(to_date('30/11/2009', 'DD/MM/YYYY'),
  6                                                         to_date('01/04/2009', 'DD/MM/YYYY')))))
  7  ORDER BY quarter
  8  /
 
QUARTER
-------
2009-Q2
2009-Q3
2009-Q4
2010-Q1
 
SQL> 
fsitja
Post duplicated somehow...

Edited by: fsitja on Jan 22, 2010 11:58 AM
Frank Kulash
Hi,

You're getting a quarter for each 3 values of LEVEL.
To get one more quarter, add 3 to the limit on LEVEL:
select distinct 
        to_char(qdate,'YYYYQ') quarter
from 	( select  add_months ( to_date (:start_date, 'DD/MM/YYYY')
	  	  	     , m
			     ) qdate
	  from 	  ( select level m 
	  	    from   dual
		    connect by level < 3 +	-- Added
		    	       	       ceil ( months_between ( to_date (:end_date,  'DD/MM/YYYY')
		    	       	     	   	  	     , to_date (:start_date,'DD/MM/YYYY')
					     )		     )
		  )
	) 
order by quarter
;
Edited by: Frank Kulash on Jan 22, 2010 9:09 AM

By the way, you don't need all those sub-queries.
SELECT	TO_CHAR ( ADD_MONTHS ( TO_DATE (:start_date, :date_format)
		  	     , 3 * (LEVEL - 1)
			     )
		, 'YYYYQ'
		)
FROM	dual
CONNECT BY	LEVEL <= 1 + CEIL ( MONTHS_BETWEEN ( TO_DATE (:end_date,   :date_format)
		      	     		      	   , TO_DATE (:start_date, :date_format)
					      	   )
			     	   / 3
			     	   )
;
6363
This maybe
SQL> var start_date varchar2(10)
SQL> var end_date varchar2(10)
SQL> exec :start_date := '01/05/2010'; :end_date := '09/15/2010'

PL/SQL procedure successfully completed.

SQL> select
  2      to_char(quarter_date, 'YYYY')
  3          || to_char( trunc(months_between(quarter_date, trunc(quarter_date,'Y')) / 3) + 1,'00')
  4  from
  5      (
  6      select
  7        trunc(add_months(to_date(:start_date,'MM/DD/YYYY'),3 * level),'Q') quarter_date
  8      from
  9        dual
 10      connect by
 11        level <=
 12          (months_between(to_date(:end_date,'MM/DD/YYYY'),to_date(:start_date,'MM/DD/YYYY')) + 3) / 3
 13      );

TO_CHAR
-------
2010 02
2010 03
2010 04

SQL> exec :start_date := '04/01/2009'; :end_date := '12/31/2009'

PL/SQL procedure successfully completed.

SQL> /

TO_CHAR
-------
2009 03
2009 04
2010 01
fsitja
Isn't it 1 level per month in this case? That's the distinct's doing I believe:
SQL> SELECT DISTINCT to_char(qdate, 'YYYY') || '-Q' || to_char(qdate, 'Q') quarter, m
  2    FROM (SELECT add_months(to_date('01/04/2009', 'DD/MM/YYYY'), m) qdate, m
  3            FROM (SELECT LEVEL m
  4                    FROM dual
  5                  CONNECT BY LEVEL - 3 < ceil(months_between(to_date('30/11/2009', 'DD/MM/YYYY'),
  6                                                         to_date('01/04/2009', 'DD/MM/YYYY')))))
  7  ORDER BY quarter;
 
QUARTER          M
------- ----------
2009-Q2          2
2009-Q2          1
2009-Q3          4
2009-Q3          3
2009-Q3          5
2009-Q4          6
2009-Q4          8
2009-Q4          7
2010-Q1         10
2010-Q1          9
 
10 rows selected
 
SQL> 
659537
select distinct to_char(qdate,'YYYYQ') quarter
from ( select add_months(to_date('1/4/2009','DD/MM/YYYY'),m) qdate
from ( select level m 
from dual
connect by level < ceil(months_between(add_months(to_date('31/12/2009','DD/MM/YYYY'),3),to_date('1/4/2009','DD/MM/YYYY')))
)
) order by quarter
Frank Kulash
Hi,
fsitja wrote:
Isn't it 1 level per month in this case? That's the distinct's doing I believe: ...
Right; thanks.
I corrected my earlier message.

I find it's confusing to use DISTINCT, and inefficient to generate all the months only to do a DISTINCT later. Sometimes, inefficient execution can be justified by simpler coding, but I don't think that's the case here.
Repeated from my earlier mesage, here's how I would do this:
SELECT	TO_CHAR ( ADD_MONTHS ( TO_DATE (:start_date, :date_format)
		  	     , 3 * (LEVEL - 1)
			     )
		, 'YYYYQ'
		)
FROM	dual
CONNECT BY	LEVEL <= 1 + CEIL ( MONTHS_BETWEEN ( TO_DATE (:end_date,   :date_format)
		      	     		      	   , TO_DATE (:start_date, :date_format)
					      	   )
			     	   / 3
			     	   )
;
6363
Frank Kulash wrote:
Hi,
fsitja wrote:
Isn't it 1 level per month in this case? That's the distinct's doing I believe: ...
Right; thanks.
I corrected my earlier message.

I find it's confusing to use DISTINCT, and inefficient to generate all the months only to do a DISTINCT later.
Yes, I believe I sort of said that right at the beginning, just had the output format wrong

4046203

An on second attempt forgot I could use 'YYYYQ' format which you just reminded me about - so the corrected version should have been just
SQL> var start_date varchar2(10)
SQL> var end_date varchar2(10)
SQL> exec :start_date := '04/01/2009'; :end_date := '12/31/2009'

PL/SQL procedure successfully completed.

SQL> select
  2    to_char(trunc(add_months(to_date(:start_date,'MM/DD/YYYY'),3 * level),'Q'),'YYYYQ') quarter_date
  3  from
  4    dual
  5  connect by
  6    level <=
  7      (months_between(to_date(:end_date,'MM/DD/YYYY'),to_date(:start_date,'MM/DD/YYYY')) + 3) / 3;

QUART
-----
20093
20094
20101
748467
Thanks for your input guys!
748467
Suddenly there are still problems with getting the right quarters... I have skipped the CONNECT BY clauses and used the following function:
CREATE OR REPLACE function SAI.fnc_get_sales_quarters(p_start_date in date, p_end_date in date)
return sales_quarters_t
pipelined
is
  l_num_quarters number;
  l_start_date   date;
  l_out          number;
begin
  l_num_quarters := round(months_between(p_end_date,p_start_date)) / 3 + 2;
  for i in 1..l_num_quarters 
  loop
    l_start_date := trunc(add_months(p_start_date, (i -1) * 3),'Q');
    l_out        := to_number(to_char(l_start_date,'YYYY')) || to_number(to_char(l_start_date,'Q'));
    pipe row(l_out);
  end loop;
  return;
end;
/
When I the startdate is: 23 jun 2009 and the enddate is: 23 jul 2009 the function had to returned:

20092
20093
20094

but the function returned:

20092
20093

Anyone knows what's going wrong?
Aketi Jyuuzou
I like recursive with clause B-)
I have used PostgreSQL8.4 because I do not have Oracle11gR2 :8}
with recursive rec(Val) as(
select date '2009-04-01'
union all
select (Val+InterVal '3 month')::date
  from rec
 where Val < date '2009-11-30')
select to_char(Val,'yyyy-q') from rec;

 to_char
---------
 2009-2
 2009-3
 2009-4
 2010-1
748467
Nice thing, but I need the function that I've created...
Frank Kulash
Hi,

The problem is using MONTHS_BETWEEN (y, x) to find the number of quarters.
If x is February 8, 2010 and y is March 8, 2010, then MONTHS_BETWEEN returns 1, and we're talking about 1 quarter, but
if x is March 8, 2010 and y is April 8, 2010, then MONTHS_BETWEEN still returns 1, and we're talking about 1 quarters.
Let's TRUNCate x to the beginning of its quarter, so that we know differences < 3 months will always be in only one quarter.
Try this:
CREATE OR REPLACE function SAI.fnc_get_sales_quarters(p_start_date in date, p_end_date in date)
return sales_quarters_t
pipelined
is
  l_num_quarters number;
  l_start_date   date	:= TRUNC (p_start_date, 'Q');
  l_out          number;
begin
  l_num_quarters := FLOOR ( months_between ( p_end_date
  		    	   		   , l_start_date
					   )
			  / 3
			  ) + 2;
  for i in 1..l_num_quarters 
  loop
    l_out        := to_number (to_char (l_start_date, 'YYYYQ'));
    l_start_date := add_months (l_start_date,  3);
    pipe row(l_out);
  end loop;
  return;
end;
/ 
748467
Thanks Frank...

I think the following code should also do the trick:
CREATE OR REPLACE function fnc_get_sales_quarters(p_start_date in date, p_end_date in date)
return sales_quarters_t
pipelined
is
  l_temp_date    date;
  l_out          number;
begin
   l_temp_date := trunc(p_start_date,'Q');
   while l_temp_date < trunc(p_end_date)
   loop
     l_out := to_char(l_temp_date,'yyyyq');
     pipe row(l_out);
     l_temp_date := add_months(l_temp_date,3);
   end loop;
   l_out := to_char(l_temp_date,'yyyyq');
   pipe row(l_out);
end;
/
Solomon Yakobson
Frank Kulash wrote:

The problem is using MONTHS_BETWEEN (y, x) to find the number of quarters.
Well, yes. But the real problem is using a counter-intuitive approach to solving sequential items task. We have a function that returns set of start-of-quarter dates for quarters between start_dt and end_dt. Assume function is f(dt)=(qtr<sub>1</sub>,...,qtr<sub>N+1</sub>). So we start with f(start_dt) and keep going with f(start_dt + 3*N) and then stop when f(start_dt + 3*(N+1)) > end_dt. Most of solutions (and not just in this post) use CONNECT BY LEVEL or PL/SQL LOOP. Problem is that instead of ending CONNECT BY LEVEL or PL/SQL LOOP based on condition against task function* (in this particular case it is qtr<sub>N1</sub> > end_date) posters try to use task function arguments+* to precalculate N and use it as stop condition which in many cases, including this, is counter-intuitive. Compare complex logic of converting start_dt, end_dt to N to simple logic of:
CREATE OR REPLACE function SAI.fnc_get_sales_quarters(p_start_date in date, p_end_date in date)
return sales_quarters_t
pipelined
is
  l_start_date   date	:= TRUNC (p_start_date, 'Q');
  l_out          number;
begin
  loop
    l_out        := to_number (to_char (l_start_date, 'YYYYQ'));
    pipe row(l_out);
    l_start_date := add_months (l_start_date,  3);
    exit when l_start_date > p_end_date
  end loop;
  return;
end;
/ 
Same applies to CONNECT BY solution:
select  trunc(to_date (:start_date,'DD/MM/YYYY') + (level - 1) * 3,'Q') quarter
  from  dual
  connect by trunc(to_date (:start_date,'DD/MM/YYYY') + (level - 1) * 3,'Q') <= to_date (:end_date,'DD/MM/YYYY')
  order by quarter
;
SY.
Frank Kulash
Hi,
user9033582 wrote:
I think the following code should also do the trick:
CREATE OR REPLACE function fnc_get_sales_quarters(p_start_date in date, p_end_date in date)
return sales_quarters_t
pipelined
is
l_temp_date    date;
l_out          number;
begin
l_temp_date := trunc(p_start_date,'Q');
while l_temp_date < trunc(p_end_date) ...
I think you want <=, not just <, in the WHILE condition. Otherwise, you'll miss one quarter when p_end_date happens to be the beginning of a quarter.
What is the purpose of TRUNC here?
I think you want:
   while l_temp_date <= p_end_date
1 - 18
Locked Post
New comments cannot be posted to this locked post.

Post Details

Locked on Mar 8 2010
Added on Jan 22 2010
18 comments
12,635 views