Re: Update PK Violation

From: "Scott Marlowe" <scott(dot)marlowe(at)gmail(dot)com>
To: "Franklin Haut" <franklin(dot)haut(at)gmail(dot)com>
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: Update PK Violation
Date: 2008-01-15 20:20:19
Message-ID: dcc563d10801151220i1e62a36dn2e208901b1ea88dc@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

On Jan 15, 2008 3:03 PM, Franklin Haut <franklin(dot)haut(at)gmail(dot)com> wrote:
> Hi all,
>
> i have a problem with one update sentence sql.
>
> example to produce:
>
> create table temp (num integer primary key, name varchar(20));
>
> insert into temp values (1, 'THE');
> insert into temp values (2, 'BOOK');
> insert into temp values (3, 'IS');
> insert into temp values (4, 'ON');
> insert into temp values (5, 'THE');
> insert into temp values (6, 'RED');
> insert into temp values (7, 'TABLE');
>
> -- now i need insert new row at position 4, for this i need increase the
> field 'num' 4 to 5, 5 to 6, 6 to 7 and 7 to 8
> update temp set num = num + 1 where num > 5;
> -- but this give an key violation error, because the postgresql try
> change row 4 to 5 and the 5 exist.
> --- the big question is... have one way to the command (update temp

SNIP

> set num = num + 1 where num > 5;) works ?
> -- consideration, i can´t delete the primary key
> -- using PG 8.2 / Windows

Normally, I'd say you're doing it wrong, as PKs aren't supposed to
change all the time. You're using this as a uniquer sequencer number,
not a real PK. However, there are a few different work-arounds you
might be able to implement, depending on your needs.

1: Drop the unique index in a transaction, put it back before you're done.

This method has some serious locking issues you might run into, but if
you only have one or two processes accessing your data, and it all
happens in a quick succession, it should be safe. Since, if something
in your activity fails, the transaction rolls back and your original
unique index is still there.

begin;
drop index abc_pk_dx;
update table set id = id + 1 where id > 5;
create index unique abc_pk_dx on table (id);
commit;

2: Put gaps in your sequence. Since you're not likely to have
billions of billions of words, you can put gaps in your id sequence.
I.e. 0, 20, 40, 60, 80, 100, so on. Add a word in the middle just give
it a number like 50. If you run out of space, then lock the table and
spread it out again. Shouldn't be necessary very often, if ever. If
you need unlimited space between each, then switch to numeric.

3: Use an id to numeric lookup table. I.e. have a table hanging off
to the side that has the REAL sequence numbers, and don't ever change
them in the original table, but have another column there (or in the
side table) that connects them to each other.

Hope one of those ideas helps.

In response to

Responses

Browse pgsql-sql by date

  From Date Subject
Next Message Rodrigo E. De León Plicet 2008-01-15 20:40:13 Re: SQL dealing with subquery
Previous Message Joost Kraaijeveld 2008-01-15 19:42:31 Re: Is DATETIME an ANSI-SQL type?