Re: Re-2: Problem with SqlState=23505 when inserting rows

From: Adrian Klaver <adrian(dot)klaver(at)aklaver(dot)com>
To: Werner Kuhnle <wek(at)kuhnle(dot)com>, pgsql-general(at)lists(dot)postgresql(dot)org
Subject: Re: Re-2: Problem with SqlState=23505 when inserting rows
Date: 2020-01-16 16:49:54
Message-ID: d582e51a-d8eb-554d-23a4-74496da12233@aklaver.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

On 1/16/20 12:14 AM, Werner Kuhnle wrote:
> Thanks Michael und Adrian for your answers.
> I think that
> "
> My guess is that the SERIAL was defined for the column, then the data
> was added with id values, but the counter for the sequence behind the
> SERIAL was not updated to a value greater the the last id added.
> "
> is a correct description of what happens.
> For avoiding the need of an additional command for updating the sequence
> before every insert statement:

You don't have to update the sequence before every INSERT. For each
SERIAL column do this one time:

1) Find current max(id) for the column.

2) Update the the sequence:

select setval('seq_name', max_id);

From then on the sequence will automatically increment the id with
values that are greater then those in the table and you will not get the
unique violation errors. The caveat is that if you manually supply an id
value then all bets are off.

For more information on sequences see:

https://www.postgresql.org/docs/12/sql-createsequence.html

For SERIAL see:

https://www.postgresql.org/docs/12/datatype-numeric.html#DATATYPE-SERIAL

If you want more control over what is accepted for the value then you
can use an IDENTITY column:

https://www.postgresql.org/docs/12/sql-createtable.html

GENERATED { ALWAYS | BY DEFAULT } AS IDENTITY [ ( sequence_options ) ]

As to below, no.

> Is there a way to specify the desired behaviour
> (that PG always provides conflict-free id values, eg. max(id)+1 when
> id values are not given explicitly in the INSERT statement)
> already whend defining(!) the table in the CREATE TABLE statement ?

>
> Original Message processed by david® <https://david.tobit.software>
>
> *Re: Problem with SqlState=23505 when inserting rows*15. Januar
> 2020, 17:51 Uhr
> *Von* Michael Lewis <mailto:mlewis(at)entrata(dot)com>
> *An* Werner Kuhnle <mailto:wek(at)kuhnle(dot)com>
> *Cc* PostgreSQL General <mailto:pgsql-general(at)lists(dot)postgresql(dot)org>
>
>
>
>
> On Wed, Jan 15, 2020 at 9:41 AM Werner Kuhnle <wek(at)kuhnle(dot)com
> <mailto:wek(at)kuhnle(dot)com>> wrote:
>
> I've tried to using the newer definition:
> id int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY
> but that does not solve the problem.
>
> Is there a way to define id columns to that when the database
> provides values,
> it recognizes already existing values avoiding conflicts.
>
>
> You'll need to run something like the below to set the next value to
> the max current value. You'll just have to figure out the name of
> the sequence that is automatically created whether you use the
> pseudo type serial, or the newer IDENTITY option. Both are
> implemented with a sequence.
>
> --set sequence to max ID on a table
> select setval( 'table_name_id_seq', ( select max(id) + 1 from
> table_name ) );
>

--
Adrian Klaver
adrian(dot)klaver(at)aklaver(dot)com

In response to

Browse pgsql-general by date

  From Date Subject
Next Message Richard van der Hoff 2020-01-16 16:50:25 Inexplicable duplicate rows with unique constraint
Previous Message Justin 2020-01-16 16:38:15 Re: Can I do this?