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



So the following wouldn't work?
select p.k1, p.k2, p.k3, p.k4
from vkparent p exception join vkchild c on
p.k1=c.k1 and
p.k2=c.k2 and
p.k3=c.k3 and
p.k4=c.k4 and
c.status = 'A'

Cannot test this as I am in a meeting without access to the AS/400

Alan Shore
E-mail : ASHORE@xxxxxxxx
Phone [O] : (631) 200-5019
Phone [C] : (631) 880-8640
'If you're going through hell, keep going.'
Winston Churchill


-----Original Message-----
From: MIDRANGE-L [mailto:midrange-l-bounces@xxxxxxxxxxxxxxxxxx] On Behalf Of Rob Berendt
Sent: Friday, December 20, 2019 8:06 AM
To: Midrange Systems Technical Discussion <midrange-l@xxxxxxxxxxxxxxxxxx>
Subject: [EXTERNAL] RE: Help with SQL

I think you're right. That STATUS column throws a wrinkle in it.
create table vkparent (
k1 char(1),
k2 char(1),
k3 char(1),
k4 char(1),
primary key(k1, k2, k3, k4)
)
;
create table vkchild (
k1 char(1),
k2 char(1),
k3 char(1),
k4 char(1),
status char(1),
k5 char(1),
d1 char(1),
primary key(k1, k2, k3, k4, k5)
);

insert into vkparent values('A', 'A', 'A', 'A'); insert into vkparent values('B', 'B', 'B', 'B'); insert into vkparent values('C', 'C', 'C', 'C'); insert into vkparent values('D', 'D', 'D', 'D'); insert into vkchild values('A', 'A', 'A', 'A', 'A', '1', 'X'); insert into vkchild values('B', 'B', 'B', 'B', 'I', '1', 'X'); insert into vkchild values('D', 'D', 'D', 'D', 'I', '1', 'X'); insert into vkchild values('D', 'D', 'D', 'D', 'A', '2', 'Y');

select p.k1, p.k2, p.k3, p.k4
from vkparent p
where (p.k1, p.k2, p.k3, p.k4) not in ( select c.k1, c.k2, c.k3, c.k4 from vkchild c where c.status = 'A') ; This line won't get what you want because 'D' has both an active and an inactive row.
select p.k1, p.k2, p.k3, p.k4, c.status
from vkparent p left outer join vkchild c on
p.k1=c.k1 and p.k2=c.k2 and p.k3=c.k3 and p.k4=c.k4 where c.status is null or c.status<>'A'
;
l

Rob Berendt
--
IBM Certified System Administrator - IBM i 6.1 Group Dekko Dept 1600 Mail to: 2505 Dekko Drive
Garrett, IN 46738
Ship to: Dock 108
6928N 400E
Kendallville, IN 46755
http://www.dekko.com


-----Original Message-----
From: MIDRANGE-L <midrange-l-bounces@xxxxxxxxxxxxxxxxxx> On Behalf Of Vinay Gavankar
Sent: Friday, December 20, 2019 7:28 AM
To: Midrange Systems Technical Discussion <midrange-l@xxxxxxxxxxxxxxxxxx>
Subject: Re: Help with SQL

CAUTION: This email originated from outside of the organization. Do not click links or open attachments unless you recognize the sender and know the content is safe.


I don't think the Left Outer Join or Exception join would work, as the JOIN
would be on 4 keys, and the sql would return only the records where the
JOIN is not successful. So it would return only records where there is no
match in child table. Maybe I am wrong, but that is what my test sql did.


On Fri, Dec 20, 2019 at 7:19 AM Rob Berendt <rob@xxxxxxxxx> wrote:

I did a simple google for sql list missing child rows
Basically it boiled down to a few choices between
NOT EXISTS
NOT IN
LEFT OUTER JOIN
EXCEPTION JOIN

Rob Berendt
--
IBM Certified System Administrator - IBM i 6.1
Group Dekko
Dept 1600
Mail to: 2505 Dekko Drive
Garrett, IN 46738
Ship to: Dock 108
6928N 400E
Kendallville, IN 46755
http://www.dekko.com


-----Original Message-----
From: MIDRANGE-L <midrange-l-bounces@xxxxxxxxxxxxxxxxxx> On Behalf Of
Vinay Gavankar
Sent: Friday, December 20, 2019 7:14 AM
To: Midrange Systems Technical Discussion <midrange-l@xxxxxxxxxxxxxxxxxx>
Subject: Help with SQL

CAUTION: This email originated from outside of the organization. Do not
click links or open attachments unless you recognize the sender and know
the content is safe.


Hi,

We have a Table with K1, K2, K3, K4 as Primary keys with about 800 million
records. A child table, which is partitioned, has K1, K2, K3, K4, K5 (Seq
Number) as Primary keys and a Status field (value of A or I) with about 10
billion records. Child table having no record for the 4 keys is possible,
though highly unlikely.

I need to get a list of records (just the key fields) from the main Table,
which has no record in the child table with Status = 'A' (may or may not
have an 'I' Status record).

Can someone please help me with some efficient sql code to achieve this?
TIA.

Vinay
--
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@xxxxxxxxxxxx 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@xxxxxxxxxxxx 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@xxxxxxxxxxxx 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 ...

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.