Here's how I would start...

Using Common Table Expression, I would produce a result set that sums the details, by orderID, then join that to the header, where dtl.total<>hdr.total...


With
Dtl (orderID, total) as
( Select ord_id, sum(extd_amt)
From OrderDtl
Group by ord_id
)

Select Hdr.*, Dtl.total
From OrderHdr Hdr inner join
Dtl on (Hdr.ord_id = Dtl.orderID)
Where Hdr.total <> Dtl.total


In brief, the WITH clause is used to define a virtual table consisting of two columns (orderID and total), which is defined "as" the embedded select statement. That statement proceses the details file and sums the extended line amount, grouped by ord_id. This means that one row will be produced for each ord_id, with the sum of all rows matching that ord_id.

The main select (specified after the common table expression (CTE)) selects all columns from the header, and the total column from the detail summary, joining for all rows with matching order id. The where clause selects only rows where the header total is not equal to the detail summary total.

hth,
Eric DeLong

-----Original Message-----
From: midrange-l-bounces@xxxxxxxxxxxx
[mailto:midrange-l-bounces@xxxxxxxxxxxx]On Behalf Of Tim Gornall
Sent: Thursday, June 12, 2008 1:59 PM
To: midrange-l@xxxxxxxxxxxx
Subject: SQL statement example request




Calling all SQL gurus,
I wanted to do an adhoc report using SQL earlier today. I only know the
very basics when it comes to SQL, but I what to start digging deeper so to
speak. I ended up banging it out in RPG. I would like to see how you guys
would have done it with a SQL statement.

I have a header file with a total field. This total should match the sum of
the transactions in a detail file. I needed to list all header records that
did not match, displaying the header amount and the sum of the detail.

Sounds easy, eh? And it may be. Just in case someone has nothing better to
do...

Thanks in advance, Tim



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.