This is a question I've seen a few times, and
had to research, so I figured I'd share the
answer.
-------------------------------------------------
drop table test;
--
create table test ( a text, b text );
-- unique values
insert into test values ( 'x', 'y');
insert into test values ( 'x', 'x');
insert into test values ( 'y', 'y' );
insert into test values ( 'y', 'x' );
-- duplicate values
insert into test values ( 'x', 'y');
insert into test values ( 'x', 'x');
insert into test values ( 'y', 'y' );
insert into test values ( 'y', 'x' );
-- one more double duplicate
insert into test values ( 'x', 'y');
--
select oid, a, b from test;
--
-- select duplicate rows
--
select o.oid, o.a, o.b from test owhere exists ( select 'x' from test i where i.a = o.a
and i.b = o.b and i.oid < o.oid );
--
-- delete duplicate rows
--
-- Note: PostgreSQL dosn't support aliases on
-- the table mentioned in the from clause
-- of a delete.
--
delete from test where exists ( select 'x' from test i where i.a = test.a
and i.b = test.b and i.oid < test.oid );
--
-- Let's see if it worked.
--
select oid, a, b from test;
--
-- Delete duplicates with respect to a only, ignoring
-- the value in b. Note, the first deletion leaves the
-- first oid with the unique values and removes subsequent
-- ones, in this delete we reverse the direction of the <
-- to save the last oid, and remove the previous ones.
--
delete from test where exists ( select 'x' from test i where i.a = test.a
and i.oid > test.oid );
--
-- Let's see if it worked.
--
select oid, a, b from test;