Thread: There can be only one

There can be only one

From
Jason Dusek
Date:

Consider a table of providers, for which one is the default. For example, payment providers:

CREATE TABLE payment_via ( id            uuid PRIMARY KEY, provider      text NOT NULL, keys          hstore NOT NULL DEFAULT ''
);

Here we store together the name of the provider — medici, paypal — with access tokens needed to use a certain payment account. How shall we store which one is the default? Ideally, we’d be able to ensure there is but one default.

CREATE TABLE payment_via ( id            uuid PRIMARY KEY, provider      text NOT NULL, keys          hstore NOT NULL DEFAULT '', is_default    boolean NOT NULL DEFAULT FALSE
);

How shall we state the constraint? The obvious thing would seem to be:

CREATE TABLE payment_via ( id            uuid PRIMARY KEY, provider      text NOT NULL, keys          hstore NOT NULL DEFAULT '', is_default    boolean NOT NULL DEFAULT FALSE, EXCLUDE (is_default USING AND)
);

However, this is a syntax error. There is always:

CREATE TABLE payment_via ( id            uuid PRIMARY KEY, provider      text NOT NULL, keys          hstore NOT NULL DEFAULT '', is_default    boolean NOT NULL DEFAULT FALSE, EXCLUDE (is_default USING =) WHERE (is_default)
);

but this seems awkward and I was hoping there was some way to use AND as an operator.

Re: There can be only one

From
Andreas Kretschmer
Date:
Create a partial unique index on is_default.

Am 11. Oktober 2015 09:41:08 MESZ, schrieb Jason Dusek <jason.dusek@gmail.com>:

Consider a table of providers, for which one is the default. For example, payment providers:

CREATE TABLE payment_via ( id            uuid PRIMARY KEY, provider      text NOT NULL, keys          hstore NOT NULL DEFAULT ''
);

Here we store together the name of the provider — medici, paypal — with access tokens needed to use a certain payment account. How shall we store which one is the default? Ideally, we’d be able to ensure there is but one default.

CREATE TABLE payment_via ( id            uuid PRIMARY KEY, provider      text NOT NULL, keys          hstore NOT NULL DEFAULT '', is_default    boolean NOT NULL DEFAULT FALSE
);

How shall we state the constraint? The obvious thing would seem to be:

CREATE TABLE payment_via ( id            uuid PRIMARY KEY, provider      text NOT NULL, keys          hstore NOT NULL DEFAULT '', is_default    boolean NOT NULL DEFAULT FALSE, EXCLUDE (is_default USING AND)
);

However, this is a syntax error. There is always:

CREATE TABLE payment_via ( id            uuid PRIMARY KEY, provider      text NOT NULL, keys          hstore NOT NULL DEFAULT '', is_default    boolean NOT NULL DEFAULT FALSE, EXCLUDE (is_default USING =) WHERE (is_default)
);

but this seems awkward and I was hoping there was some way to use AND as an operator.


--
Diese Nachricht wurde von meinem Android-Mobiltelefon mit K-9 Mail gesendet.

Re: There can be only one

From
Andreas Kretschmer
Date:
Andreas Kretschmer <andreas@a-kretschmer.de> wrote:

> Create a partial unique index on is_default.

as an example:


test=# CREATE TABLE payment_via (
  id            int PRIMARY KEY,
  provider      text NOT NULL,
  keys          hstore NOT NULL DEFAULT '',
  is_default    boolean NOT NULL DEFAULT FALSE
);
CREATE TABLE
test=*# create unique index idx_default on payment_via(is_default) where
is_default;
CREATE INDEX
test=*# insert into payment_via values (1, 'foo','', true);
INSERT 0 1
test=*# insert into payment_via values (2, 'bla','', false);
INSERT 0 1
test=*# insert into payment_via values (3, 'blubb','', true);
ERROR:  duplicate key value violates unique constraint "idx_default"
DETAIL:  Key (is_default)=(t) already exists.
test=*#




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°