55 lines
1.4 KiB
SQL
55 lines
1.4 KiB
SQL
WITH
|
|
preagg AS (
|
|
SELECT
|
|
coalesce(director,'None') director
|
|
,coalesce(quota_rep_descr,'None') quota_rep_descr
|
|
,part
|
|
,bill_cust_descr
|
|
,ship_cust_descr
|
|
,order_month
|
|
,doc->>'stamp' stamp
|
|
,logid
|
|
,tag
|
|
,sum(value_usd) FILTER (WHERE iter = 'copy') sales
|
|
,sum(cost_usd) FILTER (WHERE iter = 'copy') scogs
|
|
,sum(value_usd) FILTER (WHERE iter <> 'copy') sales_adj
|
|
,sum(cost_usd) FILTER (WHERE iter <> 'copy') scogs_adj
|
|
FROM
|
|
rlarp.osm_pool
|
|
LEFT OUTER JOIN rlarp.osm_log ON
|
|
id = logid
|
|
WHERE
|
|
order_season = 2022
|
|
GROUP BY
|
|
director
|
|
,quota_rep_descr
|
|
,part
|
|
,bill_cust_descr
|
|
,ship_cust_descr
|
|
,order_month
|
|
,doc->>'stamp'
|
|
,logid
|
|
,tag
|
|
)
|
|
SELECT
|
|
director
|
|
,quota_rep_descr
|
|
,to_char(sum(sales),'999,999,999') sales
|
|
,to_char(sum(sales - scogs),'999,999,999') margin
|
|
,to_char(sum(sales_adj) FILTER (WHERE tag <> 'Initial Build'),'999,999,999') sales_adj
|
|
,to_char(sum(sales_adj - scogs_adj) FILTER (WHERE tag <> 'Initial Build'),'999,999,999') margin_adj
|
|
,count(DISTINCT logid) FILTER (WHERE tag <> 'Initial Build') "# of changes"
|
|
,COUNT(logid) FILTER (WHERE tag <> 'Initial Build') "# of rows added"
|
|
,(max(stamp) FILTER (WHERE tag <> 'Initial Build'))::timestamptz "last edit"
|
|
FROM
|
|
preagg
|
|
GROUP BY
|
|
GROUPING SETS (
|
|
(director,quota_rep_descr),
|
|
(director),
|
|
()
|
|
)
|
|
ORDER BY
|
|
director
|
|
,quota_rep_descr
|