| From: | Tim Middleton <x(at)vex(dot)net> |
|---|---|
| To: | pgsql-sql(at)postgresql(dot)org |
| Subject: | Re: How to get list of days between two dates? |
| Date: | 2006-06-07 05:06:29 |
| Message-ID: | 200606070106.29950.x@vex.net |
| Views: | Whole Thread | Raw Message | Download mbox | Resend email |
| Thread: | |
| Lists: | pgsql-sql |
This is going to be ugly, and I can't even say for sure it's right (and if by
chance it is right, I imagine it still might be more efficient broken up in a
function), but intrigued by learning about generate_series() from Scott
Marlows response I fiddled until I got the results specified like this...
SELECT dt, event_name
FROM (
SELECT (mn.d + s.d) AS dt
FROM (
SELECT min(start_time) FROM test_events) AS mn(d),
generate_series(0, (
SELECT (extract('epoch' from age(max(end_time),
min(start_time)))/86400)::integer
FROM test_events))
AS s(d))
AS x
JOIN test_events AS y ON (dt BETWEEN start_time AND end_time)
ORDER BY dt, event_name;
dt | event_name
------------+--------------
2006-05-01 | First Event
2006-05-02 | First Event
2006-05-02 | Second Event
2006-05-03 | First Event
2006-05-04 | First Event
2006-05-04 | Third Event
2006-05-05 | Third Event
2006-05-07 | Fourth Event
(8 rows)
--
Tim Middleton | Vex.Net | "Who is Ungit?" said he, still holding
x(at)veX(dot)net | VexTech.ca | my hands. --C.S.Lewis (TWHF)
| From | Date | Subject | |
|---|---|---|---|
| Next Message | Daryl Richter | 2006-06-07 11:29:00 | Re: Advanced Query |
| Previous Message | Michael Glaesemann | 2006-06-07 00:05:21 | Re: Join issue |