I think it is a lot more clear with a correlated sub-select.
In any case, try to do the sum before the join so you avoid all the mess with max() and so on. Here's another way:
with sumdtlfile (dtlkey, sumdtlqty) as
(
select dtlkey, sum(dtlqty) from dtlfile group by dtlkey
)
select hdrfile.hdrkey, hdrfile.totqty, sumdtlfile.sumdtlqty from hdrfile left join sumdtlfile on sumdtlfile.dtlkey=hdrfile.hdrkey
where hdrfile.totqty<>sumdtlfile.sumdtlqty
This form has the advantage of allowing more than one field to be extracted from the detail file.
-----Original Message-----
From: midrange-l-bounces@xxxxxxxxxxxx [mailto:midrange-l-bounces@xxxxxxxxxxxx] On Behalf Of Stone, Joel
Sent: Wednesday, April 03, 2013 12:24 PM
To: 'Midrange Systems Technical Discussion'
Subject: RE: how to join header and detail records
Does this seem more self-documenting when joining 2,3,more files than a join? Or is a join easier to read a month later and figure out what your intentions were?
Thanks
-----Original Message-----
From: midrange-l-bounces@xxxxxxxxxxxx [mailto:midrange-l-bounces@xxxxxxxxxxxx] On Behalf Of Dan Kimmel
Sent: Wednesday, April 03, 2013 12:23 PM
To: Midrange Systems Technical Discussion
Subject: RE: how to join header and detail records
I prefer to use a correlated query for this instead of join. It's usually faster.
select totqty, (select sum(dtlqty) from dtlfile b where b.dtlkey=a.hdrkey) as sumdtlqty from hdrfile a where totqty<>sumdtlqty
-- untested so syntax may need adjustment
-----Original Message-----
From: midrange-l-bounces@xxxxxxxxxxxx [mailto:midrange-l-bounces@xxxxxxxxxxxx] On Behalf Of Stone, Joel
Sent: Wednesday, April 03, 2013 11:53 AM
To: 'Midrange Systems Technical Discussion'
Subject: SQL: how to join header and detail records
I have an order header and detail file with one to many.
The order header has TOTQTY, which is the sum of all detail quantities.
The order detail has DTLQTY, which is one line's qty.
If I do a join of the two files and there is one HDR and five DTL records, there will now be FIVE rows.
I want to compare the sum of the DTLQTY to the single TOTQTY value.
I can use SUM(DTLQTY) to provide the sum of the detail.
What is a good way to provide the TOTQTY? I don't want to use SUM(TOTQTY) as this would give a result 5 times the correct value.
Is MAX(TOTQTY) what people generally use?
But that seems to be misleading since I am not really looking for the max value, as all rows contain the same value for a header column.
Should I be grouping the detail PRIOR to the join, so there is only ONE header value?
But it seems like the SQL stmt is SO much simpler if I do the join first.
Any ideas?
Thanks!
______________________________________________________________________
This outbound email has been scanned for all viruses by the MessageLabs Skyscan service.
For more information please visit
http://www.symanteccloud.com ______________________________________________________________________
--
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.
--
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.
________________________________________________________________________
This inbound email has been scanned for all viruses by the MessageLabs SkyScan
service.
________________________________________________________________________
______________________________________________________________________
This outbound email has been scanned for all viruses by the MessageLabs Skyscan service.
For more information please visit
http://www.symanteccloud.com
______________________________________________________________________
As an Amazon Associate we earn from qualifying purchases.