From: | "Oliveiros d'Azevedo Cristina" <oliveiros(dot)cristina(at)marktest(dot)pt> |
---|---|
To: | "Oliveiros d'Azevedo Cristina" <oliveiros(dot)cristina(at)marktest(dot)pt>, "Jira, Marcel" <Marcel(dot)Jira(at)wu(dot)ac(dot)at>, <pgsql-sql(at)postgresql(dot)org> |
Subject: | Re: Merge overlapping time-periods |
Date: | 2011-06-15 16:49:53 |
Message-ID: | D5459212DE8D4037AA3B3AC0892ED3C2@marktestcr.marktest.pt |
Views: | Whole Thread | Raw Message | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-sql |
Hello again, Marcel.
I tried this and it seems to work on the example you provided, iif my understanding is correct and you want the ID=2 to have just one record on final output.
That makes sense to me because
2 2000-01-15 2000-03-31
2 2000-04-01 2000-04-15
are in direct sequence (IMHO) as much as
1 2000-01-01 2000-03-31
1 2000-04-01 2000-05-31
are. Isn't my understanding correct?
Best,
Oliveiros
(SELECT x."ID",x."BEG",x."END"
FROM mytable x
LEFT JOIN
(
SELECT a."ID" as xid ,a."BEG" as xbeg,a."END" as xend,b."ID" as yid,b."BEG" as ybeg,b."END" as yend
FROM mytable a
JOIN mytable b
ON a."ID" = b."ID"
AND (( ((a."BEG",a."END") OVERLAPS (b."BEG",b."END"))
OR ((b."BEG" - a."END") = 1))
AND (a."BEG" <> b."BEG")
AND (b."END" <> a."END"))
) y
ON (((yid = x."ID")
AND (ybeg = x."BEG")
AND (yend = x."END"))
OR ((xid = x."ID")
AND (xbeg = x."BEG")
AND (xend = x."END")))
WHERE yid IS NULL)
UNION (
SELECT x."ID",MIN(x."BEG"),MAX(x."END")
FROM mytable x
LEFT JOIN
(
SELECT a."ID" as xid,a."BEG" as xbeg,a."END" as xend,b."ID" as yid,b."BEG" as ybeg,b."END" as yend
FROM mytable a
JOIN mytable b
ON a."ID" = b."ID"
AND (( ((a."BEG",a."END") OVERLAPS (b."BEG",b."END"))
OR ((a."BEG" - b."END") = 1))
AND (a."BEG" <> b."BEG")
AND (b."END" <> a."END"))
) y
ON (((yid = x."ID")
AND (ybeg = x."BEG")
AND (yend = x."END"))
OR ((xid = x."ID")
AND (xbeg = x."BEG")
AND (xend = x."END")))
WHERE yid IS NOT NULL
GROUP BY x."ID"
)
Howdy, Marcel,
In the example output you provided the ID = 2 should have just one record...Ain't I right?
Best,
Oliveiros
----- Original Message -----
From: Jira, Marcel
To: 'pgsql-sql(at)postgresql(dot)org'
Sent: Wednesday, June 15, 2011 4:23 PM
Subject: [SQL] Merge overlapping time-periods
Hi!
Although I try for some time, I am not able to write an SQL-Query that can do the following:
I have a very big table (let's call it "mytable") with information like this:
ID BEG END
1 2000-01-01 2000-03-31
1 2000-04-01 2000-05-31
1 2000-04-15 2000-07-31
1 2000-09-01 2000-10-31
2 2000-02-01 2000-03-15
2 2000-01-15 2000-03-31
2 2000-04-01 2000-04-15
3 2000-06-01 2000-06-15
3 2000-07-01 2000-07-15
There's an ID and time periods defined by a start value (BEG) and an end value (END)
I want to merge all periods belonging to the same ID, iff their time periods are overlapping or in a direct sequence.
Therefore the result should somehow look like this:
ID BEG END1 2000-01-01 2000-07-311 2000-09-01 2000-10-312 2000-01-15 2000-03-312 2000-04-01 2000-04-153 2000-06-01 2000-06-153 2000-07-01 2000-07-15
I tried using "WITH RECURSIVE" but I didn't succeed.
My server is PostgreSQL 8.4. Unfortunately I can't do anything like update or install some fancy module.
Thank you for your help!
Best regards,
Marcel Jira
From | Date | Subject | |
---|---|---|---|
Next Message | Samuel Gendler | 2011-06-15 17:23:51 | finding gaps in temporal data |
Previous Message | Oliveiros d'Azevedo Cristina | 2011-06-15 16:37:51 | Re: Merge overlapping time-periods |