Re: Update PK Violation

From: Franklin Haut <franklin(dot)haut(at)gmail(dot)com>
To: Scott Marlowe <scott(dot)marlowe(at)gmail(dot)com>, pgsql-sql(at)postgresql(dot)org, achill(at)matrix(dot)gatewaynet(dot)com
Subject: Re: Update PK Violation
Date: 2008-01-16 18:07:32
Message-ID: 478E47E4.20501@gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

<!DOCTYPE html PUBLIC "-//W3C//DTD HTML 4.01 Transitional//EN">
<html>
<head>
<meta content="text/html;charset=ISO-8859-1" http-equiv="Content-Type">
</head>
<body bgcolor="#ffffff" text="#000000">
Scott Marlowe wrote:
<blockquote
cite="middcc563d10801151220i1e62a36dn2e208901b1ea88dc(at)mail(dot)gmail(dot)com"
type="cite">
<pre wrap="">On Jan 15, 2008 3:03 PM, Franklin Haut <a class="moz-txt-link-rfc2396E" href="mailto:franklin(dot)haut(at)gmail(dot)com">&lt;franklin(dot)haut(at)gmail(dot)com&gt;</a> wrote:
</pre>
<blockquote type="cite">
<pre wrap="">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 &gt; 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
</pre>
</blockquote>
<pre wrap=""><!---->
SNIP

</pre>
<blockquote type="cite">
<pre wrap="">set num = num + 1 where num &gt; 5;) works ?
-- consideration, i can&acute;t delete the primary key
-- using PG 8.2 / Windows
</pre>
</blockquote>
<pre wrap=""><!---->
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 &gt; 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.

</pre>
</blockquote>
<font face="Courier New, Courier, monospace" size="+1">You solve my
problem when you say " </font><font size="+1"><br>
I'd say you're doing it wrong, as PKs aren't supposed to change all the
time.
</font><font face="Courier New, Courier, monospace" size="+1">"<br>
<br>
I changed my table and add a new colum what is part of the PK.<br>
<br>
another solution is that</font><font size="+1"><tt> </tt><tt>Achilleas
Mantzios and you propoused using <br>
negative values.<br>
<br>
</tt></font>
<pre wrap=""><font size="+1"> update temp set num = -1*num where num &gt;=5;
insert into temp values (5,'NOT';);
update temp set num = (-1*num) + 1 where num &lt; 0;</font></pre>
<br>
<font face="Courier New, Courier, monospace" size="+1">thanks for all!!</font><br>
<font face="Courier New, Courier, monospace"><br>
<br>
</font>
</body>
</html>

Attachment Content-Type Size
unknown_filename text/html 3.8 KB

In response to

Browse pgsql-sql by date

  From Date Subject
Next Message Kevin Jenkins 2008-01-16 23:15:41 How to test/read a stored procedure that returns a boolean?
Previous Message Bryan Emrys 2008-01-16 17:34:53 Re: SQL dealing with subquery