× The internal search function is temporarily non-functional. The current search engine is no longer viable and we are researching alternatives.
As a stop gap measure, we are using Google's custom search engine service.
If you know of an easy to use, open source, search engine ... please contact support@midrange.com.



If you were looking to see when duplicates occurred, I would have
personally preferred...
select item
from file
group by item
having count(1) > 1

So if this query was running periodically, I would send off an email as
soon as at least one record was read from this.

On Tue, Jan 19, 2016 at 11:02 AM, Dan <dan27649@xxxxxxxxx> wrote:

Michael,

Thanks for your example. I've never seen the PARTITION BY before, but I
get the concept. The nice thing about your example is that I found it
useful to list only the 2nd duplicate, so I was able to change the last
line from "<= 2" to "= 2". (This helps me identify when the duplicates
started to occur, and it was quite illuminating for determining the root
cause.)

- Dan

On Mon, Jan 18, 2016 at 4:30 PM, Michael Schutte <mschutte369@xxxxxxxxx>
wrote:

you're right, order by needs added to the over(...) I missed that.

On Mon, Jan 18, 2016 at 4:12 PM, <rob@xxxxxxxxx> wrote:

Somewhere in there is a need for an order by PRDATER (process date).
But the analytical
row_number() over...
should be the light that clicks on for the OP.

Rob Berendt


From: Michael Schutte <mschutte369@xxxxxxxxx>
To: Midrange Systems Technical Discussion <midrange-l@xxxxxxxxxxxx

Date: 01/18/2016 04:05 PM
Subject: Re: Complex (for me) SQL question
Sent by: "MIDRANGE-L" <midrange-l-bounces@xxxxxxxxxxxx>



Add () to the row_number, remove group by from the over(...)

On Mon, Jan 18, 2016 at 3:53 PM, Michael Schutte <
mschutte369@xxxxxxxxx>
wrote:

Oops, didn't finish reading.

with sum1 as (
select PRPRDN from HPRDFA
group by PRPRDN
HAVING COUNT(1) > 1
), results as (
select HPRDFA.*, row_number over(partition by PRPRDN group by PRPRDN)
row_number_by_item
from HPRDFA
where PRPRDN in (select PRPRDN from sum1) )
select * from results
where row_number_by_item <= 2

On Mon, Jan 18, 2016 at 3:51 PM, Michael Schutte <
mschutte369@xxxxxxxxx>
wrote:

Would this suffice?

select PRPRDN from HPRDFA
group by PRPRDN
HAVING COUNT(1) > 1
order by PRPRDN

Or
with sum1 as (
select PRPRDN from HPRDFA
group by PRPRDN
HAVING COUNT(1) > 1
)
select * from HPRDFA
where PRPRDN in (select PRPRDN from sum1)

--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing list
To post a message email: MIDRANGE-L@xxxxxxxxxxxx
To subscribe, unsubscribe, or change list options,
visit: http://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx
Before posting, please take a moment to review the archives
at http://archive.midrange.com/midrange-l.

Please contact support@xxxxxxxxxxxx for any subscription related
questions.


As an Amazon Associate we earn from qualifying purchases.

This thread ...

Follow-Ups:
Replies:

Follow On AppleNews
Return to Archive home page | Return to MIDRANGE.COM home page

This mailing list archive is Copyright 1997-2024 by midrange.com and David Gibbs as a compilation work. Use of the archive is restricted to research of a business or technical nature. Any other uses are prohibited. Full details are available on our policy page. If you have questions about this, please contact [javascript protected email address].

Operating expenses for this site are earned using the Amazon Associate program and Google Adsense.