Deleting duplicates
From PostgreSQL wiki
Jump to navigationJump to searchDeleting duplicates
Works with PostgreSQL
8.4+
Written in
SQL
Depends on
Nothing
A frequent question in IRC is how to delete rows that are duplicates over a set of columns, keeping only the one with the lowest ID.
This query does that for all rows of tablename having the same column1, column2, and column3.
DELETE FROM tablename
WHERE id IN (
SELECT
id
FROM (
SELECT
id,
row_number() OVER w as rnum
FROM tablename
WINDOW w AS (
PARTITION BY column1, column2, column3
ORDER BY id
)
) t
WHERE t.rnum > 1);
Sometimes a timestamptz field is used instead of an ID field.