| From: | Bruno Wolff III <bruno(at)wolff(dot)to> | 
|---|---|
| To: | Randall Lucas <rlucas(at)tercent(dot)net> | 
| Cc: | pgsql-sql(at)postgresql(dot)org | 
| Subject: | Re: UNIQUE boolean: only one row may be "true" | 
| Date: | 2003-05-06 17:23:54 | 
| Message-ID: | 20030506172354.GA21510@wolff.to | 
| Views: | Whole Thread | Raw Message | Download mbox | Resend email | 
| Thread: | |
| Lists: | pgsql-sql | 
On Tue, May 06, 2003 at 12:01:20 -0400,
  Randall Lucas <rlucas(at)tercent(dot)net> wrote:
> 
> Hi folks,
> 
> After a late night of SQL hacking, my brain fizzed out:
> 
> How shall I create a constraint such that only one row may be 'true'?  
> Rephrased, may I place a WHERE clause in a UNIQUE constraint, or 
> alternatively, may I use a CHECK constraint with an aggregate?
You can't use a select in a check constraint.
Using a partial index seems to do what you want. Do something like:
create unique index thing_idx on thing (thing_group_id, is_main_thing)
  where is_main_thing = true;
> 
> Example:
> 
> CREATE TABLE thing (
>  thing_id 			serial primary key,
>  thing_group_id 	int not null references thing_group(thing_group_id),
>  is_main_thing_p 	boolean not null default 'f',
> -- there may be only one main thing per group:
>  unique (thing_group_id, is_main_thing_p='t')
> -- or else something like:
> -- check (count (*) from thing where thing_group_id=NEW.thing_group_id 
> and is_main_thing_p = 't' <2)
> );
> 
> Best,
> 
> Randall
> 
> 
> ---------------------------(end of broadcast)---------------------------
> TIP 3: if posting/reading through Usenet, please send an appropriate
> subscribe-nomail command to majordomo(at)postgresql(dot)org so that your
> message can get through to the mailing list cleanly
| From | Date | Subject | |
|---|---|---|---|
| Next Message | chester c young | 2003-05-06 17:26:04 | Re: UNIQUE boolean: only one row may be "true" | 
| Previous Message | Michael Teter | 2003-05-06 17:13:49 | Re: UNIQUE boolean: only one row may be "true" |