Andreas <maps...@gmx.net> wrote: > Hi, > > I've got a log-table that records events regarding other objects. > Those events have a state that shows the progress of further work on > this event. > They can be open, accepted or rejected. > > I don't want to be able to insert addition events regarding an object X > as long there is an open or accepted event. > On the other hand as soon as the current event gets rejected a new event > should be possible. > > So there may be several rejected events at any time but no more than 1 > open or accepted entry. > > Can I do this within the DB so I don't have to trust the client app? > > The layout looks like this > Table : objects ( id serial, .... ) > > Table : event_log ( id serial, oject_id integer references objects.id, > state integer, date_created timestamp, ... ) > where state is 0 = open, -1 = reject, 1 = accept
test=# create table log (state int not null, check (state in (-1,0,1))); CREATE TABLE Time: 37,527 ms test=*# commit; COMMIT Time: 0,556 ms test=# create unique index on log((case when state in (0,1) then 1 else null end)); CREATE INDEX Time: 18,558 ms test=*# insert into log values (-1); INSERT 0 1 Time: 0,611 ms test=*# insert into log values (-1); INSERT 0 1 Time: 0,274 ms test=*# insert into log values (-1); INSERT 0 1 Time: 0,248 ms test=*# insert into log values (1); INSERT 0 1 Time: 0,294 ms test=*# insert into log values (0); ERROR: duplicate key value violates unique constraint "log_case_idx" DETAIL: Key (( CASE WHEN state = ANY (ARRAY[0, 1]) THEN 1 ELSE NULL::integer END))=(1) already exists. test=!# HTH. 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° -- Sent via pgsql-sql mailing list (pgsql-sql@postgresql.org) To make changes to your subscription: http://www.postgresql.org/mailpref/pgsql-sql