Thread: week ending

week ending

From
Keith Worthington
Date:
Hi All,

I just finished writing a query that groups data based on the week number.

SELECT EXTRACT(week FROM col_a) AS week_number,       sum(col_b) AS col_b_total  FROM foo WHERE foobar GROUP BY
EXTRACT(weekFROM col_a) ORDER BY EXTRACT(week FROM col_a);
 

I would like to generate the starting date or ending date based on this 
number.  IOW instead of telling the user "week number" which they won't 
understand I would like to provide either Friday's date for "week 
ending" or Monday's date for "week beginning".

SELECT <something> AS week_ending,       sum(col_b) AS col_b_total  FROM foo WHERE foobar GROUP BY EXTRACT(week FROM
col_a)ORDER BY EXTRACT(week FROM col_a);
 

-- 

Kind Regards,
Keith


Re: week ending

From
"Rodrigo De Leon"
Date:
On 7/5/06, Keith Worthington <KeithW@narrowpathinc.com> wrote:
> Hi All,
>
> I just finished writing a query that groups data based on the week number.
>
> SELECT EXTRACT(week FROM col_a) AS week_number,
>         sum(col_b) AS col_b_total
>    FROM foo
>   WHERE foobar
>   GROUP BY EXTRACT(week FROM col_a)
>   ORDER BY EXTRACT(week FROM col_a);
>
> I would like to generate the starting date or ending date based on this
> number.  IOW instead of telling the user "week number" which they won't
> understand I would like to provide either Friday's date for "week
> ending" or Monday's date for "week beginning".
>
> SELECT <something> AS week_ending,
>         sum(col_b) AS col_b_total
>    FROM foo
>   WHERE foobar
>   GROUP BY EXTRACT(week FROM col_a)
>   ORDER BY EXTRACT(week FROM col_a);
>
> --
>
> Kind Regards,
> Keith

select
max(case when (to_char(col_a,'d') between 2 and 6) then col_a end) as
week_ending,
sum(col_b) as col_b_total from foo
where foobar
group by extract(year from col_a), extract(week from col_a)
order by extract(year from col_a), extract(week from col_a);

Regards,

Rodrigo


Re: week ending

From
"Aaron Bono"
Date:
On 7/5/06, Keith Worthington <KeithW@narrowpathinc.com> wrote:
Hi All,

I just finished writing a query that groups data based on the week number.

SELECT EXTRACT(week FROM col_a) AS week_number,
        sum(col_b) AS col_b_total
   FROM foo
  WHERE foobar
  GROUP BY EXTRACT(week FROM col_a)
  ORDER BY EXTRACT(week FROM col_a);

I would like to generate the starting date or ending date based on this
number.  IOW instead of telling the user "week number" which they won't
understand I would like to provide either Friday's date for "week
ending" or Monday's date for "week beginning".

SELECT <something> AS week_ending,
        sum(col_b) AS col_b_total
   FROM foo
  WHERE foobar
  GROUP BY EXTRACT(week FROM col_a)
  ORDER BY EXTRACT(week FROM col_a);

Try this.  It puts Saturday as the Friday before it and Sunday as the Firday after so if you want Saturday or Sunday to be on different weeks you will need to do a little tweaking but this should get you going.

SELECT
   date_trunc('day', col_a + (interval '1 day' * (5 - extract(dow from col_a)))) AS week_ending,
   sum(col_b) AS col_b_total
FROM foo
GROUP BY
   date_trunc('day', col_a + (interval '1 day' * (5 - extract(dow from col_a))))