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



On 29 Mar 2013 12:13, CRPence wrote:
On 29 Mar 2013 09:28, Stone, Joel wrote:
How can I display the "sum(AFNLAPL),sum(AESTAPL) " ?

I am trying to aggregate all the child record qty's into one field
and list them as a parent field?

select
ACNTNMB,AFNLAPL,sum(AFNLAPL),sum(AESTAPL)
from jstone/conterms a
where exists (
select acntnmb,sum(AFNLAPL),sum(AESTAPL)
from jstone/applsjct b
where ACNTNMB < 300000
and a.ACNTNMB = b.ACNTNMB
and a.ADVSNCD = b.ADVSNCD
group by ACNTNMB
)

Perhaps the following is a proper translation of the intentions for
the above:

select
ACNTNMB,AFNLAPL,sumAFNLAPL,sumAESTAPL
from jstone/conterms a
left join
lateral (
select b.acntnmb
,sum(b.AFNLAPL) as sumAFNLAPL
,sum(b.AESTAPL) as sumAESTAPL
from jstone/applsjct b
where b.ACNTNMB < 300000
and a.ACNTNMB = b.ACNTNMB
and a.ADVSNCD = b.ADVSNCD
group by ACNTNMB
) as s
on a.ACNTNMB = s.ACNTNMB
where s.ACNTNMB is not null

The above request without the WHERE clause [or using IS NULL instead of the IS NOT NULL for the predicate in that WHERE clause], allows for a review of what values did not find a match from the selection of the secondary\joined-to file.

Of course, an INNER JOIN effects the same set as the above query, but without using the IS NULL predicate. Originally I had chosen the LEFT JOIN to cause the NULL value for a mis-compare, in order to explicitly mimic the EXISTS... but that is unnecessary. Thus the above could be written instead, as:

select
a.ACNTNMB,a.AFNLAPL,s.sumAFNLAPL,s.sumAESTAPL
from jstone/conterms as a
inner join
lateral (
select b.acntnmb
,sum(b.AFNLAPL) as sumAFNLAPL
,sum(b.AESTAPL) as sumAESTAPL
from jstone/applsjct as b
where b.ACNTNMB < 300000
and a.ACNTNMB = b.ACNTNMB
and a.ADVSNCD = b.ADVSNCD
group by b.ACNTNMB
) as s
on a.ACNTNMB = s.ACNTNMB


As an Amazon Associate we earn from qualifying purchases.

This thread ...


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.