Birgitta,
Thank you for this. That is much more efficient with the CASE statements.
I'll work on the additional indexes once I've finalized the entire statement.
Thanks again!
Greg
-----Original Message-----
From: RPG400-L [mailto:rpg400-l-bounces@xxxxxxxxxxxxxxxxxx] On Behalf Of Birgitta Hauser
Sent: Saturday, March 07, 2020 12:49 PM
To: 'RPG programming on IBM i' <rpg400-l@xxxxxxxxxxxxxxxxxx>
Subject: RE: Most efficient SQL approach
I have rewritten your SQL statement (without any OLAP function).
There is no need for 5 CTEs (3 are enough)
... you may also select the COM_NBR directly in your CTES.
Make sure that there are indexes for all files (except V_CUSTMSTR) over
COM_NBR, ENT_MBR, ORDDATE. Eventually EVIs (Encoded Vector Indexes) built
over ORDDATE, COM_NBR, ENT_MBR with Include clauses SUM(OPN_AMT) or
SUM(SHP_AMT) will speed up your query. (I don't know how many rows must be
accumulated)
For V_CUSTMSTR there should be an index over COM_NBR and ENT_NBR.
With Orders as (Select Com_Nbr, Ent_Nbr, Sum(OPN_AMT) as BOOK_YTD
From V_Orders
Where OrdDate between '2020-01-01' and '2020-03-04'
Group By Com_Nbr, Ent_Nbr),
Inv as (Select Com_Nbr, Ent_Nbr,
Sum(Case When Inv_Date between '2020-01-01' and
'2020-03-04' Then SHP_AMT Else 0 End) as NET_YTD,
Sum(Case When Inv_Date between '2019-01-01' and
'2019-12-31' Then SHP_AMT Else 0 End) as PRV_YR_TOTAL,
Sum(Case When Inv_Date between '2019-01-01' and
'2019-03-04' Then SHP_AMT Else 0 End) as NET_PRV_YTD
From V_INVOICES
Where INV_Date between '2019-01-01' and '2020-03-04'
Group By Com_Nbr, Ent_Nbr),
OrdSA as (Select Com_Nbr, Ent_Nbr, Sum(ORD_AMT) BOOK_PRV_YTD
From V_ORDERSA
Where OrdDate between '2019-01-01' and '2020-03-04'
Group By Com_Nbr, Ent_Nbr)
Select CUS.COM_NBR, CUS_CUST_NBR, CUS.CUSTNAME, -- more here
Coalesce(BOOK_YTD, 0) as BOOK_YTD,
Coalesce(NET_YTD, 0) as NET_YTD,
Coalesce(PRV_YEAR_TOTAL, 0) as PRV_YEAR_TOTAL
Coalesce(NET_PRV_YTD, 0) as NET_PRV_YTD
From V_CUSTMSTR as CUS Left Join Orders O on CUS.COM_NBR = O.COM_NBR and
CUS.ENT_NBR = O.ENT_NBR,
Left Join Inv i on CUS.COM_NBR = I.COM_NBR and
CUS.ENT_NBR = I.ENT_NBR,
Left Join OrdSA A on CUS.COM_NBR = A.COM_NBR and
CUS.ENT_NBR = A.ENT_NBR
Where CUS.COM_NBR = '012';
Mit freundlichen Grüßen / Best regards
Birgitta Hauser
"Shoot for the moon, even if you miss, you'll land among the stars." (Les
Brown)
"If you think education is expensive, try ignorance." (Derek Bok)
"What is worse than training your staff and losing them? Not training them
and keeping them!"
"Train people well enough so they can leave, treat them well enough so they
don't want to." (Richard Branson)
-----Original Message-----
From: RPG400-L <rpg400-l-bounces@xxxxxxxxxxxxxxxxxx> On Behalf Of Greg
Wilburn
Sent: Freitag, 6. März 2020 22:03
To: RPG programming on IBM i <rpg400-l@xxxxxxxxxxxxxxxxxx>
Subject: RE: Most efficient SQL approach
I'm not sure I understand how OLAP functions fit in.
If I could get one CTE with Order totals current year-to-date and previous
year-to-date by customer, and the same for Invoice Total by customer
-----Original Message-----
From: RPG400-L [mailto:rpg400-l-bounces@xxxxxxxxxxxxxxxxxx] On Behalf Of
Birgitta Hauser
Sent: Friday, March 06, 2020 1:04 PM
To: 'RPG programming on IBM i' <rpg400-l@xxxxxxxxxxxxxxxxxx>
Subject: RE: Most efficient SQL approach
I'd use Common Tables Expressions in composition with OLAP Functions
Mit freundlichen Grüßen / Best regards
Birgitta Hauser
"Shoot for the moon, even if you miss, you'll land among the stars." (Les
Brown)
"If you think education is expensive, try ignorance." (Derek Bok) "What is
worse than training your staff and losing them? Not training them and
keeping them!"
"Train people well enough so they can leave, treat them well enough so they
don't want to." (Richard Branson)
-----Original Message-----
From: RPG400-L <rpg400-l-bounces@xxxxxxxxxxxxxxxxxx> On Behalf Of Greg
Wilburn
Sent: Freitag, 6. März 2020 17:52
To: RPG programming on IBM i <rpg400-l@xxxxxxxxxxxxxxxxxx>
Subject: Most efficient SQL approach
I am rewriting an old RPG report using SQL (and SQL views I already have).
The "report" generates a database table as output
I need one row for each customer. In each row I need columns for several
sales figures that can be found in two other views.
I have SQL views for the Customer, Invoices and Orders.
I currently have it written where each sales figure is a separate
sub-select. Note that the "where" clause for each is slightly different.
It seems like this could be written more efficiently... but I'm not sure
what approach to take
1. Use common table expressions?
2. Create the output table, then use separate SQL expressions to insert
each of the summed values?
This is a simplified version of the code (for simplicity I've replaced the
RPG variables with constant values).
SELECT CUS.COM_NBR, CUS.CUST_NBR, CUS.CUST_NAME, (more here), (select
coalesce(sum(opn_amt),0) from V_ORDERS where com_nbr=cus.com_nbr and
ent_nbr=cus.ent_nbr and
ord_date>='2020-01-01' and ord_date<='2020-03-04') as BOOK_YTD,
(select coalesce(sum(shp_amt),0) from V_INVOICES where com_nbr=cus.com_nbr
and ent_nbr=cus.ent_nbr and
inv_date>='2020-01-01' and inv_date<='2020-03-04' )as NET_YTD,
(select coalesce(sum(shp_amt),0) from V_INVOICES where com_nbr=cus.com_nbr
and ent_nbr=cus.ent_nbr and
inv_date>='2019-01-01' and inv_date<='2019-03-04' ) as
PREV_YR_TOTAL, (select coalesce(sum(shp_amt),0) from V_INVOICES where
com_nbr=cus.com_nbr and ent_nbr=cus.ent_nbr and
inv_date>='2019-01-01' and inv_date<='2019-03-04' ) as
NET_PREV_YTD, (select coalesce(sum(ord_amt),0) from V_ORDERSA where
com_nbr=cus.com_nbr and ent_nbr=cus.ent_nbr and
ord_date>='2019-01-01' and ord_date<='2019-03-04') as BOOK_PREV_YTD
from V_CUSTMSTR as CUS where CUS.COM_NBR='012';
Thanks,
Greg
--
This is the RPG programming on IBM i (RPG400-L) mailing list To post a
message email: RPG400-L@xxxxxxxxxxxxxxxxxx To subscribe, unsubscribe, or
change list options,
visit:
https://lists.midrange.com/mailman/listinfo/rpg400-l
or email: RPG400-L-request@xxxxxxxxxxxxxxxxxx
Before posting, please take a moment to review the archives at
https://archive.midrange.com/rpg400-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 RPG programming on IBM i (RPG400-L) mailing list To post a
message email: RPG400-L@xxxxxxxxxxxxxxxxxx To subscribe, unsubscribe, or
change list options,
visit:
https://lists.midrange.com/mailman/listinfo/rpg400-l
or email: RPG400-L-request@xxxxxxxxxxxxxxxxxx
Before posting, please take a moment to review the archives at
https://archive.midrange.com/rpg400-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 RPG programming on IBM i (RPG400-L) mailing list To post a
message email: RPG400-L@xxxxxxxxxxxxxxxxxx To subscribe, unsubscribe, or
change list options,
visit:
https://lists.midrange.com/mailman/listinfo/rpg400-l
or email: RPG400-L-request@xxxxxxxxxxxxxxxxxx
Before posting, please take a moment to review the archives at
https://archive.midrange.com/rpg400-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.