Re: Finding duplicates only.

From: "A(dot) Kretschmer" <andreas(dot)kretschmer(at)schollglas(dot)com>
To: pgsql-general(at)postgresql(dot)org
Subject: Re: Finding duplicates only.
Date: 2010-03-11 06:59:56
Message-ID: 20100311065955.GA1035@a-kretschmer.de
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

In response to Greenhorn :
> Hi,
>
> Can someone please help me with this duplicate query.
>
> I'm trying to:
>
> 1. Return duplicates only. (without including the first valid record), and

I will try to help you. Assuming this table:

test=*# select * from greenhorn order by id;
id | inspection_time
----+----------------------------
1 | 2010-03-11 07:14:14.290259
1 | 2010-03-11 07:14:14.290259
2 | 2010-03-11 07:14:14.290259
3 | 2010-03-11 07:15:14.290259
4 | 2010-03-11 07:16:14.290259
5 | 2010-03-11 07:24:14.290259
6 | 2010-03-11 07:34:14.290259
(7 rows)

The record with id=1 is twice.

> 2. Return as duplicate if the difference between a.inspection_time
> and b.inspection time is under 5 minutes.

Assuming you have a 8.4-version:

with the table above, and time-difference < 2 minutes, rows 2, 3 and 4:

test=*# select * from (
select id,
inspection_time,
lag(inspection_time) over (order by inspection_time RANGE UNBOUNDED PRECEDING)
from greenhorn
group by 1,2
) foo
where inspection_time-lag < '2minutes'::interval;

id | inspection_time | lag
----+----------------------------+----------------------------
2 | 2010-03-11 07:14:14.290259 | 2010-03-11 07:14:14.290259
3 | 2010-03-11 07:15:14.290259 | 2010-03-11 07:14:14.290259
4 | 2010-03-11 07:16:14.290259 | 2010-03-11 07:15:14.290259
(3 rows)

>
> Here's the query string I'm using to retrieve the duplicates but it is
> returning every duplicate records.
>
> select a.rego,
> a.inspection_date,
> a.inspection_time,

Why do you have 2 fields, one for date and one for time? Use one timestamp-field instead.

Regards, hope that helps, Andreas
--
Andreas Kretschmer
Kontakt: Heynitz: 035242/47150, D1: 0160/7141639 (mehr: -> Header)
GnuPG: 0x31720C99, 1006 CCB4 A326 1D42 6431 2EB0 389D 1DC2 3172 0C99

In response to

Browse pgsql-general by date

  From Date Subject
Next Message Magnus Hagander 2010-03-11 07:14:07 Re: SAS Raid10 vs SATA II Raid10 - many small reads and writes
Previous Message Tom Lane 2010-03-11 05:53:07 Re: dst question