Thread: Duplicate rows
<div class="WordSection1"><p class="MsoNormal">Is there any way to remove a duplicate row from a table? Not my db but I haveto work with it. On version 7.4 right now.<p class="MsoNormal"> <p class="MsoNormal">Edward W. Rouse<p class="MsoNormal">ComsquaredSystem, Inc.<p class="MsoNormal">770-734-5301<p class="MsoNormal"> </div>
Edward W. Rouse <erouse@comsquared.com> wrote: > Is there any way to remove a duplicate row from a table? Not my db but I have > to work with it. On version 7.4 right now. > How to select the right records? You can try to use the ctid-column, see my simple example: test=# select * from dups ;i ---1112234 (7 Zeilen) Zeit: 0,145 ms test=*# delete from dups where (ctid, i) not in (select max(ctid), i from dups group by i); DELETE 3 Zeit: 0,378 ms test=*# select * from dups ;i ---1234 (4 Zeilen) Andreas -- Really, I'm not out to destroy Microsoft. That will just be a completely unintentional side effect. (Linus Torvalds) "If I was god, I would recompile penguin with --enable-fly." (unknown) Kaufbach, Saxony, Germany, Europe. N 51.05082°, E 13.56889°
A few ways to do this: http://www.sql-ex.ru/help/select17.php > Is there any way to remove a duplicate row from a table? Not my db but I have to work with it. On version 7.4 right now. > Edward W. Rouse > Comsquared System, Inc. > 770-734-5301 >
I am trying to test this but get an error. select ctid, * from test where id < 3000000 order by id, ctid; ERROR: could not identify an ordering operator for type tid HINT: Use an explicit ordering operator or modify the query. If I do a select I get this: select ctid, * from test where id < 3000000 order by id; ctid | id | activated | wake_up_time (108,22) | 316 | f | (36,17) | 316 | f | (used 2 rows only for brevity And when I tried max(ctid) I got: ERROR: function max(tid) does not exist HINT: No function matches the given name and argument types. You may need to add explicit type casts. I appreciate all the help and this feels like I'm almost there. Thanks Edward W. Rouse -----Original Message----- From: pgsql-sql-owner@postgresql.org [mailto:pgsql-sql-owner@postgresql.org] On Behalf Of Andreas Kretschmer Sent: Tuesday, August 10, 2010 3:45 PM To: pgsql-sql@postgresql.org Subject: Re: [SQL] Duplicate rows Edward W. Rouse <erouse@comsquared.com> wrote: > Is there any way to remove a duplicate row from a table? Not my db but I have > to work with it. On version 7.4 right now. > How to select the right records? You can try to use the ctid-column, see my simple example: test=# select * from dups ;i ---1112234 (7 Zeilen) Zeit: 0,145 ms test=*# delete from dups where (ctid, i) not in (select max(ctid), i from dups group by i); DELETE 3 Zeit: 0,378 ms test=*# select * from dups ;i ---1234 (4 Zeilen) Andreas -- Really, I'm not out to destroy Microsoft. That will just be a completely unintentional side effect. (Linus Torvalds) "If I was god, I would recompile penguin with --enable-fly." (unknown) Kaufbach, Saxony, Germany, Europe. N 51.05082°, E 13.56889° -- Sent via pgsql-sql mailing list (pgsql-sql@postgresql.org) To make changes to your subscription: http://www.postgresql.org/mailpref/pgsql-sql
Solved. Because this is a 7.4 version and we used with oids by default, I can use the oids instead of the ctid to remove the duplicates. Thanks. Edward W. Rouse -----Original Message----- From: pgsql-sql-owner@postgresql.org [mailto:pgsql-sql-owner@postgresql.org] On Behalf Of Edward W. Rouse Sent: Tuesday, August 10, 2010 4:43 PM To: pgsql-sql@postgresql.org Subject: Re: [SQL] Duplicate rows I am trying to test this but get an error. select ctid, * from test where id < 3000000 order by id, ctid; ERROR: could not identify an ordering operator for type tid HINT: Use an explicit ordering operator or modify the query. If I do a select I get this: select ctid, * from test where id < 3000000 order by id; ctid | id | activated | wake_up_time (108,22) | 316 | f | (36,17) | 316 | f | (used 2 rows only for brevity And when I tried max(ctid) I got: ERROR: function max(tid) does not exist HINT: No function matches the given name and argument types. You may need to add explicit type casts. I appreciate all the help and this feels like I'm almost there. Thanks Edward W. Rouse -----Original Message----- From: pgsql-sql-owner@postgresql.org [mailto:pgsql-sql-owner@postgresql.org] On Behalf Of Andreas Kretschmer Sent: Tuesday, August 10, 2010 3:45 PM To: pgsql-sql@postgresql.org Subject: Re: [SQL] Duplicate rows Edward W. Rouse <erouse@comsquared.com> wrote: > Is there any way to remove a duplicate row from a table? Not my db but I have > to work with it. On version 7.4 right now. > How to select the right records? You can try to use the ctid-column, see my simple example: test=# select * from dups ;i ---1112234 (7 Zeilen) Zeit: 0,145 ms test=*# delete from dups where (ctid, i) not in (select max(ctid), i from dups group by i); DELETE 3 Zeit: 0,378 ms test=*# select * from dups ;i ---1234 (4 Zeilen) Andreas -- Really, I'm not out to destroy Microsoft. That will just be a completely unintentional side effect. (Linus Torvalds) "If I was god, I would recompile penguin with --enable-fly." (unknown) Kaufbach, Saxony, Germany, Europe. N 51.05082°, E 13.56889° -- Sent via pgsql-sql mailing list (pgsql-sql@postgresql.org) To make changes to your subscription: http://www.postgresql.org/mailpref/pgsql-sql -- Sent via pgsql-sql mailing list (pgsql-sql@postgresql.org) To make changes to your subscription: http://www.postgresql.org/mailpref/pgsql-sql
In response to Edward W. Rouse : > Solved. Because this is a 7.4 version and we used with oids by default, I > can use the oids instead of the ctid to remove the duplicates. Yeah, that's right ;-) Regards, Andreas -- Andreas Kretschmer Kontakt: Heynitz: 035242/47150, D1: 0160/7141639 (mehr: -> Header) GnuPG: 0x31720C99, 1006 CCB4 A326 1D42 6431 2EB0 389D 1DC2 3172 0C99