Re: checking the gaps in intervals

From: Andreas Kretschmer <akretschmer(at)spamfence(dot)net>
To: pgsql-sql(at)postgresql(dot)org
Subject: Re: checking the gaps in intervals
Date: 2012-10-06 07:55:21
Message-ID: 20121006075521.GA14696@tux
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

Andreas Kretschmer <akretschmer(at)spamfence(dot)net> wrote:

> Anton Gavazuk <antongavazuk(at)gmail(dot)com> wrote:
>
> > Hi dear community,
> >
> > Have probably quite simple task but cannot find the solution,
> >
> > Imagine the table A with 2 columns start and end, data type is date
> >
> > start end
> > 01 dec. 10 dec
> > 11 dec. 13 dec
> > 17 dec. 19 dec
> > .....
> >
> > If I have interval, for example, 12 dec-18 dec, how can I determine
> > that the interval cannot be fully covered by values from table A
> > because of the gap 14-16 dec? Looking for solution and unfortunately
> > nothing has come to the mind yet...
>
> I'm thinking about a solution with DATERANGE (PostgreSQL 9.2)...
>
>
> Are start and end including or excluding?

Okay, my solution, quick and dirty ;-)

-- that's your table:

test=*# select * from ag;
date_start | date_end
------------+------------
2012-12-01 | 2012-12-10
2012-12-11 | 2012-12-13
2012-12-17 | 2012-12-19
(3 rows)

-- now some views:
test=*# \d+ view_ag;
View "public.view_ag"
Column | Type | Modifiers | Storage | Description
----------+-----------+-----------+----------+-------------
my_range | daterange | | extended |
View definition:
SELECT daterange(ag.date_start, ag.date_end, '[]'::text) AS my_range
FROM ag;

test=*# \d+ view_ag2;
View "public.view_ag2"
Column | Type | Modifiers | Storage | Description
----------+-----------+-----------+----------+-------------
my_range | daterange | | extended |
my_lag | daterange | | extended |
View definition:
SELECT view_ag.my_range,
lag(view_ag.my_range) OVER (ORDER BY lower(view_ag.my_range)) AS my_lag
FROM view_ag;

test=*# \d+ view_ag3;
View "public.view_ag3"
Column | Type | Modifiers | Storage | Description
-----------+-----------+-----------+----------+-------------
my_range | daterange | | extended |
my_lag | daterange | | extended |
?column? | boolean | | plain |
new_range | daterange | | extended |
View definition:
SELECT view_ag2.my_range, view_ag2.my_lag,
view_ag2.my_lag -|- view_ag2.my_range,
CASE
WHEN view_ag2.my_lag -|- view_ag2.my_range THEN view_ag2.my_lag + view_ag2.my_range
ELSE view_ag2.my_range
END AS new_range
FROM view_ag2;

-- and now my select:
-- first case, the range is not included
test=*# select count(*) from view_ag3 where new_range @> '[2012-12-12,2012-12-18]';
count
-------
0
(1 row)

-- and now, the range is included
test=*# select count(*) from view_ag3 where new_range @> '[2012-12-02,2012-12-13]';
count
-------
1
(1 row)

Hope that helps, but you need the 9.2.

Andreas
--
Really, I'm not out to destroy Microsoft. That will just be a completely
unintentional side effect. (Linus Torvalds)
"If I was god, I would recompile penguin with --enable-fly." (unknown)
Kaufbach, Saxony, Germany, Europe. N 51.05082°, E 13.56889°

In response to

Browse pgsql-sql by date

  From Date Subject
Next Message Gavin Flower 2012-10-06 08:04:23 Re: checking the gaps in intervals
Previous Message Andreas Kretschmer 2012-10-06 07:44:10 Re: checking the gaps in intervals