forecast_api/route_sql/scenario_package.sql
PhilRunninger 86225ea7e5 Get pounds to update for each forecast adjustment.
Lots of cleanup here too, removing large swaths of code that are no
longer needed. Many improvements the Excel workbook, which is kept in
Teams, not git. These changes may or may not have had accompanying VBA
changes.
2023-04-27 16:54:37 -04:00

186 lines
4.5 KiB
SQL

--\timing
--explain (analyze, buffers)
WITH
mseq AS (
SELECT * FROM
(
VALUES
('01 - Jun',1)
,('02 - Jul',2)
,('03 - Aug',3)
,('04 - Sep',4)
,('05 - Oct',5)
,('06 - Nov',6)
,('07 - Dec',7)
,('08 - Jan',8)
,('09 - Feb',9)
,('10 - Mar',10)
,('11 - Apr',11)
,('12 - May',12)
) x(m,s)
)
--select * from mseq
,base AS (
SELECT
order_season
,order_month
,version
,iter
,part_descr
,bill_cust_descr
,ship_cust_descr
,SUM(units) units
,SUM(value_usd) value_usd
FROM
rlarp.osm_pool
WHERE
where_clause
AND order_season IN (2023,2024)
GROUP BY
order_season
,order_month
,version
,iter
,part_descr
,bill_cust_descr
,ship_cust_descr
)
, basket1 AS (
SELECT
part_descr
,bill_cust_descr
,ship_cust_descr
,SUM(value_usd) value_usd
FROM
base
GROUP BY
part_descr
,bill_cust_descr
,ship_cust_descr
)
,basket AS (
SELECT
part_descr
,bill_cust_descr
,ship_cust_descr
,CASE WHEN sum(value_usd) over () = 0 THEN 0 ELSE value_usd/sum(value_usd) over () END mix
FROM
basket1
ORDER BY
mix DESC
)
,months AS (
SELECT
order_season
,version
,iter
,order_month
,mseq.s seq
,sum(units) units
,sum(value_usd) value_usd
FROM
base
INNER JOIN mseq ON
mseq.m = base.order_month
GROUP BY
order_season
,version
,iter
,order_month
,s
)
,mpvt AS (
SELECT
order_month
,seq
,SUM(units) FILTER (WHERE order_season = 2023) "2023 qty"
,SUM(units) FILTER (WHERE order_season = 2024 AND iter IN ('copy','short ship','bad_ship','plan')) "2024 base qty"
,SUM(units) FILTER (WHERE order_season = 2024 AND iter NOT IN ('copy','short ship','bad_ship','plan')) "2024 adj qty"
,SUM(units) FILTER (WHERE order_season = 2024) "2024 tot qty"
,SUM(value_usd) FILTER (WHERE order_season = 2023) "2023 value_usd"
,SUM(value_usd) FILTER (WHERE order_season = 2024 AND iter IN ('copy','short ship','bad_ship','plan')) "2024 base value_usd"
,SUM(value_usd) FILTER (WHERE order_season = 2024 AND iter NOT IN ('copy','short ship','bad_ship','plan')) "2024 adj value_usd"
,SUM(value_usd) FILTER (WHERE order_season = 2024) "2024 tot value_usd"
FROM
months
GROUP BY
order_month
,seq
ORDER BY
seq ASC
)
,mlist AS (
SELECT
mseq.m order_month
,"2023 qty"
,"2024 base qty"
,"2024 adj qty"
,"2024 tot qty"
,"2023 value_usd"
,"2024 base value_usd"
,"2024 adj value_usd"
,"2024 tot value_usd"
FROM
mseq
LEFT OUTER JOIN mpvt ON
mpvt.order_month = mseq.m
ORDER BY
mseq.s ASC
)
,totals AS (
SELECT
order_season
,version
,iter
,sum(units) units
,sum(value_usd) value_usd
FROM
months
GROUP BY
order_season
,version
,iter
)
,tags AS (
SELECT DISTINCT
doc->>'tag' tag
FROM
rlarp.osm_log
WHERE
doc ? 'tag'
AND id <> 1
UNION
SELECT * FROM
(VALUES
('price'),
('volume')
) x(tag)
)
,custs AS (
SELECT
bill_cust_descr
,ship_cust_descr
,SUM(value_usd) value_usd
FROM
base
GROUP BY
bill_cust_descr
,ship_cust_descr
)
SELECT
jsonb_build_object(
'months'
,(SELECT jsonb_agg(row_to_json(months)::jsonb) FROM months)
,'mpvt'
,(SELECT jsonb_agg(row_to_json(mlist)::jsonb) FROM mlist)
,'basket'
,(SELECT jsonb_agg(row_to_json(basket)::jsonb) FROM basket)
,'totals'
,(SELECT jsonb_agg(row_to_json(totals)::jsonb) FROM totals)
,'tags'
,(SELECT jsonb_agg(tag) FROM tags)
,'customers'
,(SELECT jsonb_agg(row_to_json(custs)::jsonb) FROM custs)
) package