Thread: Update PK Violation

Update PK Violation

From
Franklin Haut
Date:
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.

-- to contornate the situation i have make
update temp set num = 8 where num = 7;
update temp set num = 7 where num = 6;
update temp set num = 6 where num = 5;
update temp set num = 5 where num = 4;

-- so then i can insert the row...
insert into temp values (5, 'NOT');

-- and obtain the result what i need.
select num, name from temp
---result ------  1, 'THE'  2, 'BOOK'  3, 'IS'  4, 'NOT'  5, 'ON'  6, 'THE'  7, 'RED'  8, 'TABLE'


--- the big question is...  have one way to the command  (update temp 
set num = num + 1  where num > 5;) works ?
-- consideration, i can´t delete the primary key
-- using PG 8.2 / Windows

Thanks for all


Franklin


Re: Update PK Violation

From
"Scott Marlowe"
Date:
On Jan 15, 2008 3:03 PM, Franklin Haut <franklin.haut@gmail.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.


Re: Update PK Violation

From
"Fernando Hevia"
Date:
> Franklin Haut 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');
> 

Couldn't figure out how to do it in one sentence, still it can be done with
a function:

CREATE OR REPLACE FUNCTION insert_value(p_num integer, p_name varchar(20))
RETURNS VOID AS
$$
declare v_num integer;
BEGIN FOR v_num in SELECT num FROM temp WHERE num >= p_num ORDER BY num DESC
LOOP    UPDATE temp SET num = num + 1 WHERE num = v_num; END LOOP; INSERT INTO temp VALUES (p_num, p_name);
END;
$$
LANGUAGE 'plpgsql' VOLATILE;


To run it:

sistema=# select insert_value(4, 'NOT');insert_value
--------------

(1 row)


sistema=# select * from temp order by num;num | name
-----+-------  1 | THE  2 | BOOK  3 | IS  4 | NOT  5 | ON  6 | THE  7 | RED  8 | TABLE
(8 rows)


Regards,
Fernando.



Re: Update PK Violation

From
Achilleas Mantzios
Date:
Στις Tuesday 15 January 2008 23:03:49 ο/η Franklin Haut έγραψε:
> Hi all,
>
> i have a problem with one update sentence sql.
>

A simple way i use:

foodb=# update temp set num = num*1000  where num >= 5;
foodb=# insert into temp values (5, 'NOT');
foodb=# update temp set num = 1 + num/1000  where num >= 6;

--
Achilleas Mantzios


Re: Update PK Violation

From
"Scott Marlowe"
Date:
On Jan 16, 2008 8:30 AM, Achilleas Mantzios
<achill@matrix.gatewaynet.com> wrote:
> Στις Tuesday 15 January 2008 23:03:49 ο/η Franklin Haut έγραψε:
> > Hi all,
> >
> > i have a problem with one update sentence sql.
> >
>
> A simple way i use:
>
> foodb=# update temp set num = num*1000  where num >= 5;
> foodb=# insert into temp values (5, 'NOT');
> foodb=# update temp set num = 1 + num/1000  where num >= 6;

That's still open to possible collisions.  Another method that avoids
them is to use negative numbers.  i.e.

update temp set num = -1*num where num >=5;
insert into temp values (5,'NOT';);
update temp set num = (-1*num) + 1 where num < 0;

Assuming you don't use negative numbers in your setup, works a charm.

However, this kind of activity screams "bad design"...  Not that I've
never found myself right smack dab in the middle of such a thing

Re: Update PK Violation

From
Franklin Haut
Date:
Scott Marlowe wrote: <blockquote cite="middcc563d10801151220i1e62a36dn2e208901b1ea88dc@mail.gmail.com"
type="cite"><prewrap="">On Jan 15, 2008 3:03 PM, Franklin Haut <a class="moz-txt-link-rfc2396E"
href="mailto:franklin.haut@gmail.com"><franklin.haut@gmail.com></a>wrote: </pre><blockquote type="cite"><pre
wrap="">Hiall,
 

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   </pre></blockquote><pre wrap="">
SNIP
 </pre><blockquote type="cite"><pre wrap="">set num = num + 1  where num > 5;) works ?
-- consideration, i can´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 > 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><fontsize="+1"><br /> I'd say you're doing it wrong, as PKs aren't supposed to change all the time. </font><font
face="CourierNew, Courier, monospace" size="+1">"<br /><br /> I changed my table and add a new colum what is part of
thePK.<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>=5; insert into temp values (5,'NOT';); update temp set num = (-1*num) + 1 where num < 0;</font></pre><br
/><fontface="Courier New, Courier, monospace" size="+1">thanks for all!!</font><br /><font face="Courier New, Courier,
monospace"><br/><br /></font>