Re: Removing duplicate rows in table

From: Andreas Kretschmer <andreas(at)a-kretschmer(dot)de>
To: pgsql-general(at)lists(dot)postgresql(dot)org
Subject: Re: Removing duplicate rows in table
Date: 2024-09-10 15:28:15
Message-ID: 642a6ec8-4ec3-4f2a-b39a-6855237a34c1@a-kretschmer.de
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: 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

In response to

Browse pgsql-general by date

  From Date Subject
Next Message Rich Shepard 2024-09-10 15:29:44 Re: Removing duplicate rows in table
Previous Message Adrian Klaver 2024-09-10 15:22:36 Re: Removing duplicate rows in table