Re: Need help writing exclusion constraint - Mailing list pgsql-general

From Daniel Popowich
Subject Re: Need help writing exclusion constraint
Date
Msg-id 19761.65150.738792.63613@io.astro.umass.edu
Whole thread Raw
In response to Need help writing exclusion constraint  (Matthew Wilson <matt@tplus1.com>)
Responses Re: Need help writing exclusion constraint
Re: Need help writing exclusion constraint
List pgsql-general
Matthew Wilson writes:
> I have a table like this:
>
> create table event(
>
>     destination_id integer not null references destination
>     (destination_id),
>
>     starts timestamp,
>     ends timestamp
> );
>
> I want to make sure that no two rows **with the same destination_id**
> overlap in time.
>
> I'm not sure how to write this exclusion constraint.  I know how to make
> the constraint to prevent any two rows from overlapping, but I want to
> allow rows to overlap as long as they don't have the same
> destination_id.

Constraint expressions can only be simple boolean expressions, so can
refer only to the column(s) of the current row you're
inserting/updating, so to refer to other records (which you'll need to
do to compare destination_ids) you need to create a
function...something along the lines of this:


  CREATE OR REPLACE FUNCTION overlap_at_dest(dest integer,
                                             s timestamp,
                                             e timestamp)
                                             returns boolean as $_$

  DECLARE
    c bigint;
  BEGIN
    select count(*) into c from event
                           where (destination_id = dest)
                                 and ((starts, ends) overlaps (s,e));
    return c = 0;
  END;

  $_$ LANGUAGE plpgsql;



Then alter your table:

    ALTER TABLE event ADD CONSTRAINT event_overlap
             CHECK(overlap_at_dest(destination_id, starts, ends));



Cheers,

Dan Popowich


pgsql-general by date:

Previous
From: "Andrus Moor"
Date:
Subject: Re: How to generate unique invoice numbers foreach day
Next
From: Tomas Vondra
Date:
Subject: Re: How to generate unique invoice numbers foreach day