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



And I will use the lateral - whait if there is no lead time item lines?

so same tables:

declare global temporary table PART_MASTER as (
select * from(values
('ABC', 1, 34),
('ABC', 2, 16),
('DEF', 1, 7),
('DEF', 2, 234)
) x(PART_NO, WHS, LEAD_TIME)
) with data with replace;

declare global temporary table LINE_ITEMS as (
select * from(values
(1, 'ABC'),
(2, 'DEF')
) x(LINE_NO, PART_NO)
) with data with replace;

*-- My solution: *







*Select * from LINE_ITEMS p left join lateral ( select * from
PART_MASTER l where P.PART_NO = L.PART_NO order by LEAD_TIME asc
limit 1) on 1=1;*



-- Tims solution:
with PARTS_BY_LOWEST_LEAD_TIME as (
select row_number() over(partition by PART_NO order by LEAD_TIME asc) as
PRIO,
X.*

from PART_MASTER X
)

select *

from LINE_ITEMS L

join PARTS_BY_LOWEST_LEAD_TIME P
on P.PART_NO = L.PART_NO and
P.PRIO = 1;


On Tue, Jan 4, 2022 at 1:17 PM Tim Fathers <tim@xxxxxxxxxxxxx> wrote:

I would use a CTE with row_number() to generate a priority sequence for
the part master rows, such that priority 1 is the part with the lowest lead
time and then join to the priority 1 row like this:


declare global temporary table PART_MASTER as (
select * from(values
('ABC', 1, 34),
('ABC', 2, 16),
('DEF', 1, 7),
('DEF', 2, 234)
) x(PART_NO, WHS, LEAD_TIME)
) with data with replace
;;

declare global temporary table LINE_ITEMS as (
select * from(values
(1, 'ABC'),
(2, 'DEF')
) x(LINE_NO, PART_NO)
) with data with replace
;;

with PARTS_BY_LOWEST_LEAD_TIME as (
select row_number() over(partition by PART_NO order by LEAD_TIME asc) as
PRIO,
X.*

from PART_MASTER X
)

select *

from LINE_ITEMS L

join PARTS_BY_LOWEST_LEAD_TIME P
on P.PART_NO = L.PART_NO and
P.PRIO = 1


Tim.





________________________________
From: MIDRANGE-L <midrange-l-bounces@xxxxxxxxxxxxxxxxxx> on behalf of
James H. H. Lampert via MIDRANGE-L <midrange-l@xxxxxxxxxxxxxxxxxx>
Sent: 03 January 2022 22:30
To: Midrange Systems Technical Discussion <midrange-l@xxxxxxxxxxxxxxxxxx>
Cc: James H. H. Lampert <jamesl@xxxxxxxxxxxxxxxxx>
Subject: SQL question

Suppose we have a line-item file, and a part master file.

The line item records have a part number. And it cross-references to the
part master file.

But if a given part is stocked in two or more warehouses, then the part
master file has a record for it at each warehouse that stocks it.

Now, suppose we have a join between the line item file and the part
master file, on the part number. For each line item, the join is
returning a record for every matching part master record.

Not especially good. Is there a way, that works in DB2/400, to limit
that to only one join record per line item? And to select, for example,
the one with the low value in the "lead time" field?

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

Please contact support@xxxxxxxxxxxxxxxxxxxx for any subscription related
questions.

Help support midrange.com by shopping at amazon.com with our affiliate
link: https://amazon.midrange.com
--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing list
To post a message email: MIDRANGE-L@xxxxxxxxxxxxxxxxxx
To subscribe, unsubscribe, or change list options,
visit: https://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxxxxxxxx
Before posting, please take a moment to review the archives
at https://archive.midrange.com/midrange-l.

Please contact support@xxxxxxxxxxxxxxxxxxxx for any subscription related
questions.

Help support midrange.com by shopping at amazon.com with our affiliate
link: https://amazon.midrange.com


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.