× 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.



I'm gonna have to learn this.

On Mon, Jan 18, 2016 at 4:24 PM, Mike Jones <mike.jones.sysdev@xxxxxxxxx>
wrote:

Hi Dan,

LATERAL joins make that simple:
--------------------------------------------------------------------
with CTE_DUPLICATES as (
select PRPRDN
from HPRDFA
group by PRPRDN
having count(*) > 1
)

select DETAIL.*
from CTE_DUPLICATES D

cross join lateral (
select H.*
from HPRDFA H
where H.PRPRDN = D.PRPRDN
order by H.PRDATER
fetch first 2 rows only
) as DETAIL

order by DETAIL.PRPRDN, DETAIL.PRDATER
--------------------------------------------------------------------

LATERAL joins => learn 'em, love 'em, use 'em...:)

The ROW_NUMBER() function can also handle that task nicely.

Mike


date: Mon, 18 Jan 2016 15:33:51 -0500
from: Dan <dan27649@xxxxxxxxx>
subject: Complex (for me) SQL question

I have a table with duplicate (by part number) rows. The following query
lists only those rows for which duplicates exist:

with sum1 as (
select PRPRDN, count(*) as count1 from HPRDFA
group by PRPRDN
order by PRPRDN)
select * from HPRDFA d
where exists (select * from sum1 s where s.PRPRDN = d.PRPRDN and
s.count1 > 1)
order by PRDATER

I need to have this query list only the first two records for each part
number (field PRPRDN), ordered by PRDATER (process date). I'm thinking
somewhere along the lines of "fetch first 2 rows only", but this will
return only two records for the entire query, not two records for each
part
number.

- Dan

--
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 ...

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.