Skip to Main Content

Breadcrumb

Question and Answer

Chris Saxon

Thanks for the question, Vik.

Asked: July 25, 2016 - 10:35 pm UTC

Last updated: July 26, 2016 - 7:33 pm UTC

Version: 12.6

Viewed 10K+ times! This question is

You Asked

Hi,

I would appreciate if someone could point me in the right direction here. How do I write this SQl statement for below.
Here is the Criteria below:
I'm trying to go back 52 weeks based on (today's date). So for next week this week will be two. Other notes Monday is starting date and Sunday is Week ending date.

This week
Week_End_Date Week
7/31/2016 1
7/24/2016 2
7/17/2016 3

next week
Week_End_Date Week
7/24/2016 1
7/17/2016 2
7/10/2016 3

I was able to get the weeks using RowNum but how do I get weekend date to do -7 instead of repeating the same date 52 times?

select TRUNC (next_day (sysdate, 'SUN')) - 7,rownum
from F21.V_HS_FISCAL_CALENDAR f
where rownum between 1 and 52
;


7/24/2016 1
7/24/2016 2
7/24/2016 3
7/24/2016 4
7/24/2016 5
7/24/2016 6




and Chris said...

You can't use rownum in a where clause like that! It'll give you incorrect results:

http://www.oracle.com/technetwork/issue-archive/2006/06-sep/o56asktom-086197.html

The query is giving you the same date because:

TRUNC (next_day (sysdate, 'SUN')) - 7


is a constant. You want this to increase for each row. So you need to subtract an additional 7 each row. To do this, multiply this by the rownum - 1:

TRUNC (next_day (sysdate, 'SUN')) - (7 * (rownum-1))


For example:

with rws as (
  select TRUNC (next_day (sysdate, 'SUN')) - (7 * (rownum-1)), rownum x 
  from dual connect by level <= 52
)
  select * from rws;

TRUNC(NEXT_DAY(SYSDATE,'SUN'))-(7*(ROWNUM-1))  X   
31-JUL-2016 00:00:00                           1   
24-JUL-2016 00:00:00                           2   
...
16-AUG-2015 00:00:00                           51  
09-AUG-2015 00:00:00                           52


Though I'm confused. I'm guessing V_HS_FISCAL_CALENDAR already has a list of dates? Why do you need to generate new ones?

Rating

  (1 rating)

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

Comments

thanks

Vikas, July 26, 2016 - 7:42 pm UTC

Thanks you! You're correct fiscal_calendar has some dates like begin date and week end date etc. I'm glad to say I figured it out by just using that table only. this query is for 53 weeks.
select distinct week_begin_date, f.week_end_date, trunc((sysdate - f.week_begin_date) /7,0)
from F21.V_HS_FISCAL_CALENDAR f
where f.week_end_date>sysdate-372 and sysdate>=week_begin_date
order by f.week_end_date desc