Re: Removing duplicate rows in table - Mailing list pgsql-general

From Andreas Kretschmer
Subject Re: Removing duplicate rows in table
Date
Msg-id 642a6ec8-4ec3-4f2a-b39a-6855237a34c1@a-kretschmer.de
Whole thread Raw
In response to Removing duplicate rows in table  (Rich Shepard <rshepard@appl-ecosys.com>)
List pgsql-general

Am 10.09.24 um 17:07 schrieb Rich Shepard:
> I've no idea how I entered multiple, identical rows in a table but I 
> want to
> delete all but one of these rows.
>
> Here's an example:
>
> bustrac=# select * from projects where proj_nbr = '4242.01';
>  proj_nbr |   proj_name    | start_date |  end_date  | description  | 
> notes 
> ----------+----------------+------------+------------+---------------+-------
>  4242.01  | Expert witness | 2008-10-15 | 2008-10-28 | Consol Energy |
>  4242.01  | Expert witness | 2008-10-15 | 2008-10-28 | Consol Energy |
>  4242.01  | Expert witness | 2008-10-15 | 2008-10-28 | Consol Energy |
>  4242.01  | Expert witness | 2008-10-15 | 2008-10-28 | Consol Energy | 
> (4 rows)
>
> How do I clean this up so there's only a single row for this project 
> number?
>
> TIA,
>
> Rich
>
>

you can use the hidden ctid-column:

postgres=# create table demo (id int, val text);
CREATE TABLE
postgres=# insert into demo values (1, 'test1');
INSERT 0 1
postgres=# insert into demo values (1, 'test1');
INSERT 0 1
postgres=# insert into demo values (1, 'test1');
INSERT 0 1
postgres=# insert into demo values (1, 'test1');
INSERT 0 1
postgres=# select ctid, * from demo;
  ctid  | id |  val
-------+----+-------
  (0,1) |  1 | test1
  (0,2) |  1 | test1
  (0,3) |  1 | test1
  (0,4) |  1 | test1
(4 rows)

postgres=# with my_ctid as (select min(ctid) from demo where id = 1 and 
val = 'test1') delete from demo using my_ctid where id=1 and val='test1' 
and ctid != my_ctid.min;
DELETE 3
postgres=# select ctid, * from demo;
  ctid  | id |  val
-------+----+-------
  (0,1) |  1 | test1
(1 row)

postgres=#


-- 
Andreas Kretschmer
CYBERTEC PostgreSQL Services and Support




pgsql-general by date:

Previous
From: Adrian Klaver
Date:
Subject: Re: Removing duplicate rows in table
Next
From: Rich Shepard
Date:
Subject: Re: Removing duplicate rows in table