Обсуждение: How to reject overlapping timespans?

Поиск
Список
Период
Сортировка

How to reject overlapping timespans?

От
Andreas
Дата:
Hi,

I need to store data that has a valid timespan with start and enddate.

objects ( id, name, ... )
object_data ( object_id referencs objects(id), startdate, enddate, ... )

nothing special, yet

How can I have PG reject a data record where the new start- or enddate 
lies between the start- or enddate of another record regarding the same 
object_id?

Also it isn't allowed that such timespans lie within another.

There can be times where no valid data exists but there can't be more 
than one valid data-record for the same point in time.




Re: How to reject overlapping timespans?

От
Andreas Kretschmer
Дата:

Andreas <maps.on@gmx.net> hat am 17. Februar 2013 um 18:02 geschrieben:
> Hi,
>
> I need to store data that has a valid timespan with start and enddate.
>
> objects ( id, name, ... )
> object_data ( object_id referencs objects(id), startdate, enddate, ... )
>
> nothing special, yet
>
> How can I have PG reject a data record where the new start- or enddate
> lies between the start- or enddate of another record regarding the same
> object_id?

With 9.2 you can use DATERANGE and exclusion constraints

test=# create table maps(id int, duration daterange, exclude using gist(id with
=, duration with &&));
NOTICE:  CREATE TABLE / EXCLUDE will create implicit index
"maps_id_duration_excl" for table "maps"
CREATE TABLE
test=*# insert into maps values (1,'(2013-01-01,2013-01-10]');
INSERT 0 1
test=*# insert into maps values (1,'(2013-01-05,2013-01-15]');
ERROR:  conflicting key value violates exclusion constraint
"maps_id_duration_excl"
DETAIL:  Key (id, duration)=(1, [2013-01-06,2013-01-16)) conflicts with existing
key (id, duration)=(1, [2013-01-02,2013-01-11)).
test=*#


Regards, Andreas



Re: How to reject overlapping timespans?

От
Andreas
Дата:
Am 17.02.2013 19:20, schrieb Andreas Kretschmer:
> Andreas <maps.on@gmx.net> hat am 17. Februar 2013 um 18:02 geschrieben:
>> I need to store data that has a valid timespan with start and enddate.
>>
>> objects ( id, name, ... )
>> object_data ( object_id referencs objects(id), startdate, enddate, ... )
>>
>> nothing special, yet
>>
>> How can I have PG reject a data record where the new start- or enddate
>> lies between the start- or enddate of another record regarding the same
>> object_id?
> With 9.2 you can use DATERANGE and exclusion constraints
>
> test=# create table maps(id int, duration daterange, exclude using gist(id with
> =, duration with &&));
> NOTICE:  CREATE TABLE / EXCLUDE will create implicit index
> "maps_id_duration_excl" for table "maps"
> CREATE TABLE
> test=*# insert into maps values (1,'(2013-01-01,2013-01-10]');
> INSERT 0 1
> test=*# insert into maps values (1,'(2013-01-05,2013-01-15]');
> ERROR:  conflicting key value violates exclusion constraint
> "maps_id_duration_excl"
> DETAIL:  Key (id, duration)=(1, [2013-01-06,2013-01-16)) conflicts with existing
> key (id, duration)=(1, [2013-01-02,2013-01-11)).
> test=*#


though I still have a 9.1.x as productive server so I'm afraid I have to 
find another way.

Thanks, Andreas   :)




Re: How to reject overlapping timespans?

От
Ben Morrow
Дата:
Quoth maps.on@gmx.net (Andreas):
> Am 17.02.2013 19:20, schrieb Andreas Kretschmer:
> > Andreas <maps.on@gmx.net> hat am 17. Februar 2013 um 18:02 geschrieben:
> >> I need to store data that has a valid timespan with start and enddate.
> >>
> >> objects ( id, name, ... )
> >> object_data ( object_id referencs objects(id), startdate, enddate, ... )
> >>
> >> nothing special, yet
> >>
> >> How can I have PG reject a data record where the new start- or enddate
> >> lies between the start- or enddate of another record regarding the same
> >> object_id?
> >
> > With 9.2 you can use DATERANGE and exclusion constraints
> 
> though I still have a 9.1.x as productive server so I'm afraid I have to 
> find another way.

If you don't fancy implementing or backporting a GiST operator class for
date ranges using OVERLAPS, you can fake one with the geometric types.
You will need contrib/btree_gist to get GiST indexes on integers.
   create extension btree_gist;
   create function point(date)    returns point   immutable language sql   as $$        select point(0, ($1 - date
'2000-01-01')::doubleprecision)   $$;
 
   create function box(date, date)   returns box   immutable language sql   as $$        select box(point($1),
point($2))  $$;
 
   create table objects_data (       object_id   integer     references objects,       startdate   date,       enddate
  date,       exclude using gist           (object_id with =, box(startdate, enddate) with &&)   );
 

You have to use 'box' rather than 'lseg' because there are no indexes
for lsegs. I don't know how efficient this will be, and of course the
unique index will probably not be any use for anything else.

Ben