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



Does the cusrbtmst have records for all customers that you care about,
or can there be sales/credits without a cusrbtmst.
Does the cusrbtmst have the category or is that only in the sales/credit
files?




Kevin Bucknum
Senior Programmer Analyst
MEDDATA/MEDTRON
Tel: 985-893-2550

-----Original Message-----
From: MIDRANGE-L [mailto:midrange-l-bounces@xxxxxxxxxxxx] On Behalf
Of Jeff Crosby
Sent: Friday, April 13, 2018 8:51 AM
To: Midrange Systems Technical Discussion
Subject: Re: Need an SQL joining lesson

Never told you the PK's

CUSRBTMST = CUSNR
DMCATMST = CTCODE
SLSALL = none (there are 6 indexes)
CRDMEDTL = none (there are 10 indexes)


All files are defined via DDL, not DDS.

These are the actual results I am expecting:

Cust YYYYMM Category Sales Credits
==== ====== ======== ======= =======
1892 201802 B 1133.29 .00
1892 201802 D 236.98 .00
1892 201802 E 1741.93 420.01
1892 201802 F 1770.11 137.76
4554 201802 B 3556.01 72.48
4554 201802 D 1004.97 7.12
4554 201802 E 2853.17 198.25
4554 201802 F 3081.09 .00
(Total) 15377.55 835.62

With this SQL:

SELECT m.cusnr, 201802 AS YYYYMM, COALESCE(s.catcd1, c.catcd1, ' ') AS
category,
COALESCE(SUM(s.itnsa), 0) AS Sales,COALESCE(SUM(c.cdtam), 0) AS
Credits
FROM DBMSTF.CUSRBTMST m
CROSS JOIN DBMSTF.DMCATMST cat
LEFT JOIN SLSHST.SLSALL s ON m.cusnr = s.cusnr AND s.catcd1 =
cat.ctcode
LEFT JOIN DBMSTF.CRDMEDTL c ON m.cusnr = c.cusnr AND c.catcd1 =
cat.ctcode
WHERE s.INVDT BETWEEN '2018-02-01' AND '2018-02-28' AND
c.DTWRTISO BETWEEN '2018-02-01' AND '2018-02-28'
GROUP BY m.CUSNR, COALESCE(s.catcd1, c.catcd1, ' ')
ORDER BY 1, 2

I get these results:

Cust YYYYMM Category Sales Credits
==== ====== ======== ======= =======
1892 201802 E 6967.72 8400.20
1892 201802 F 3540.22 5097.12
4554 201802 B 3556.01 3406.56
4554 201802 D 1004.97 163.76
4554 201802 E 5706.34 6344.00
(Total) 20775.26 23411.64

I note a few things:

1) more credit than sales, never a good thing from a business
standpoint :)

2) numbers obviously not right

3) if there are sales and no credits, no record appears and I assume
the
reverse would be true




On Thu, Apr 12, 2018 at 7:50 PM, Charles Wilt <charles.wilt@xxxxxxxxx>
wrote:

That's not going to work...

Consider
Customer
Cusnr
1

Sales
Cusnr Cat Amt
1 A 5.00
1 B 10.00

Credits
1 D -1.00
1 E -0.50

The intermediate table (before aggregation) will be
CUSNR CUSNR CAT AMT CUSNR
CAT
AMT
1 1 A 5.00 1
D
1.00-
1 1 A 5.00 1
E
.50-
1 1 B 10.00 1
D
1.00-
1 1 B 10.00 1
E
.50-

basically cross joining between sales & credits since you're joining
on just customer...

We need to add a CATEGORY_MASTER

Then our basic statement ends up with
select *
from cust cst
cross join CATEGORY_MASTER cat
left outer join sales sls on cst.cusnr = sls.cusnr
and cat.catcd1 = sls.catcd1 left outer
join
credits crd on cst.cusnr = crd.cusnr
and cat.catcd1 = crd.catcd1

And our intermediate table looks like...
CUSNR CAT CUSNR CAT AMT
CUSNR
CAT AMT
1 A 1 A 5.00
-
- -
1 B 1 B 10.00
-
- -
1 C - - -
-
- -
1 D - - -
1
D 1.00-
1 E - - -
1
E .50-

Adding SUM and group by cst.cusnr, cat.catcd1
CUSNR CAT SALES_TOTAL
CREDIT_TOTAL
1 B 10.00
-
1 E -
.50-
1 D -
1.00-
1 C -
-
1 A 5.00
-


Lets add some more sales & credits for the existing cats...
insert into sales values (1,'A',15.00), (1,'B',12.00) insert into
credits values (1,'D',-0.75), (1,'E',-.25)

CUSNR CAT SALES_TOTAL
CREDIT_TOTAL
1 B 22.00
-
1 E -
.75-
1 D -
1.75-
1 C -
-
1 A 20.00
-


So yeah, could be done without a CTE...

Charles


On Thu, Apr 12, 2018 at 5:07 PM, Mark Murphy
<jmarkmurphy@xxxxxxxxx>
wrote:

I think the CTE is overthinking it a bit here, How about this?

SELECT m.cusnr,
201802 AS YYYYMM,
COALESCE(s.catcd1, c.catcd1, ' ') AS category,
COALESCE(SUM(s.itnsa), 0) AS Sales,
COALESCE(SUM(c.cdtam), 0) AS Credits
FROM DBMSTF.CUSRBTMST m
left JOIN SLSHST.SLSALL s ON m.cusnr = s.cusnr
left JOIN DBMSTF.CRDMEDTL c ON m.cusnr = c.cusnr
WHERE s.INVDT BETWEEN '2018-02-01' AND '2018-02-28' AND
c.DTWRTISO BETWEEN '2018-02-01' AND '2018-02-28'
GROUP BY m.CUSNR, COALESCE(s.catcd1, c.catcd1, ' ')
ORDER BY 1,2,3

I think that by grouping by the categories in the individual files
seperately, you are getting every combination of record that could
exist.
But the Groupby can contain an expression, and by using the value
that
will
appear in the output, you should get the right output.

On Thu, Apr 12, 2018 at 6:42 PM, Charles Wilt
<charles.wilt@xxxxxxxxx>
wrote:

You're running into a well known issue call "fan-out"

Here's a nice animated picture
https://discourse.looker.com/t/outer-join-on-false-or-how-
i-learned-to-stop-fanning-out-and-love-the-null/4786

The FULL OUT JOIN solution that page presents is a new one to
me..I'm
going
to have to play with it. :)

How I'd normally solve the problem would be with CTEs that
summarize
the
data first, then join the CTEs.

The key is that you want a single row for Customer, Category,
YearMonth...so you use CTEs to transform the raw data into
that...
-- Note make sure DATFMT is *ISO
with sales as (
select cusnr, catcd1, substr(char(invdt),1,7) as YearMonth
sum(itnsa) as total
from slshst.slsall
where invdat between '2018-02-01' AND '2018-02-28'
group by cusnr, catcd1, substr(char(invdt),1,7) ), credits
as
(
select cusnr, catcd1, substr(char(dtwrtiso),1,7) as YearMonth
sum(cdtam) as total
from dbmstf.crdmedtl
where dtwrtiso between '2018-02-01' AND '2018-02-28'
group by cusnr, catcd1, substr(char(dtwrtiso),1,7) ),
custs_cats as (
select cst.cusnr, cat.catcd1, '2018-02' as YearMonth
from dbmstf.cusrbtmst cst
cross join CATEGORY_MASTER cat
)
select cc.cusnr, cc.catcd1, cc.YearMonth
, coalesce(sls.Total, 0) as sales_total
, coalesce(crd.total, 0) as credit_total from
custs_cats
cc
left outer join sales sls
on cc.cusnr = sls.cusnr
and cc.catcd1 = sls.catcd1
and cc.YearMonth = sls.YearMonth
left outer join credits crd
on cc.cusnr = crd.cusnr
and cc.catcd1 = crd.catcd1
and cc.YearMonth = crd.YearMonth;

Also note that a "Dates Table" or "Calendar Table", with a
YearMonth
column
among many others comes in quite handy for things like this.

Lots of date related queries are become much easier with such a
table.

Charles




On Thu, Apr 12, 2018 at 1:49 PM, Jeff Crosby <
jlcrosby@xxxxxxxxxxxxxxxx>
wrote:

Not the greatest at SQL but have a project where I think it's
a
perfect
fit
so I want to figure this out. It's ultimately going into an
RPG
program
(as an INSERT statement), but the question at the moment is
the
SQL,
not
RPG. That's why what you see below is a SELECT with stuff
hardcoded.
I
just want the right numbers first.

Some customers are going to start getting rebates. The rebate
will a percent of (sales - credits) by item category for the
month. I want
to
insert into a file the following 5 fields:

customer number
YYYYMM
category
total sales for the month
total credits for the month

There is a file of customers and their rebate percents, the
sales
file
(with the category field in it), and a credits file (with the
category
field in it). There could be both sales and credits for a
customer/category, only sales for a customer/category, or only
credits
for
a customer/category. In all 3 cases I want 1 record per
customer/category.

CUSRBTMST - rebates percents file SLSALL - sales file CRDMEDTL
-
credits file

This is the SQL I have now:

SELECT m.cusnr,
201802 AS YYYYMM,
COALESCE(s.catcd1, c.catcd1, ' ') AS category,
COALESCE(SUM(s.itnsa), 0) AS Sales,
COALESCE(SUM(c.cdtam), 0) AS Credits
FROM DBMSTF.CUSRBTMST m
JOIN SLSHST.SLSALL s ON m.cusnr = s.cusnr
JOIN DBMSTF.CRDMEDTL c ON m.cusnr = c.cusnr
WHERE s.INVDT BETWEEN '2018-02-01' AND '2018-02-28' AND
c.DTWRTISO BETWEEN '2018-02-01' AND
'2018-02-28'
GROUP BY m.CUSNR, s.catcd1, c.catcd1
ORDER BY m.CUSNR, s.catcd1, c.catcd1

That's a copy/paste from ACS run SQL scripts that I formatted
a
bit further.

The results I get have no resemblance to the actual sales and
credits.
:)

I'm joining the rebate percent file to both the sales and
credits
file.
That might be the problem, I don't know. Are 2 SELECTS
required?

Thanks for any pointers.


--


Jeff Crosby
VP Information Systems
UniPro FoodService/Dilgard
P.O. Box 13369
Ft. Wayne, IN 46868-3369
260-422-7531
direct.dilgardfoods.com

The opinions expressed are my own and not necessarily the
opinion of
my
company. Unless I say so.
--
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: https://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx 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: http://amzn.to/2dEadiD

--
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: https://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx 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: http://amzn.to/2dEadiD

--
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: https://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx 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: http://amzn.to/2dEadiD

--
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: https://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx 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: http://amzn.to/2dEadiD




--


Jeff Crosby
VP Information Systems
UniPro FoodService/Dilgard
P.O. Box 13369
Ft. Wayne, IN 46868-3369
260-422-7531
direct.dilgardfoods.com

The opinions expressed are my own and not necessarily the opinion of
my
company. Unless I say so.
--
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: https://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx 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: http://amzn.to/2dEadiD

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.