"Ben K." <bkim@xxxxxxxxxxxx> writes: > > create table mytable (myid serial primary key constraint > mytable_myid_chk check (myid = currval('mytable_myid_seq'), mydata > varchar(255), ...); > > > I'd like to clarify that this will not be a full solution, since it > will not allow update of the table unless nextval has been used in the > same sequence already. It's not a full solution anyway since it prevents any kind of update on the table due to check constraints firing even if target field not updated. See below; jerry@jerry# = create table foo (a serial check (a = currval('foo_a_seq')), b int); NOTICE: CREATE TABLE will create implicit sequence "foo_a_seq" for serial column "foo.a" CREATE TABLE jerry@jerry# = insert into foo values (default, 1); INSERT 0 1 jerry@jerry# = insert into foo values (default, 1); INSERT 0 1 jerry@jerry# = insert into foo values (default, 1); INSERT 0 1 jerry@jerry# = insert into foo values (default, 1); INSERT 0 1 jerry@jerry# = select * from foo; a | b ---+--- 1 | 1 2 | 1 3 | 1 4 | 1 (4 rows) jerry@jerry# = update foo set b=2; ERROR: new row for relation "foo" violates check constraint "foo_a_check" jerry@jerry# = > > There seems to be a hack in case of oracle that allows using currval > without nextval, but it's a hack and I don't know if there's an > equivalent in postgresql > (http://rootshell.be/~yong321/computer/sequence.txt). (Oracle seems to > have "disable" option when adding check constraint by alter table, but > the context seem a bit different from ours so may not be useful in our > case, at any rate.) > > > > > Regards > > Ben K. > Developer > http://benix.tamu.edu > > > > > ---------------------------(end of broadcast)--------------------------- > TIP 2: Don't 'kill -9' the postmaster > > ---------------------------(end of broadcast)--------------------------- > TIP 5: don't forget to increase your free space map settings > -- ------------------------------------------------------------------------------- Jerry Sievers 305 854-3001 (home) Production Database Administrator 305 321-1144 (mobil WWW E-Commerce Consultant