From 1ecadc3227f9645f54d4ab79a3c958b147fb3744 Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Tue, 12 Mar 2019 17:20:23 -0400 Subject: [PATCH] add sql files --- route_sql/get_pool.sql | 158 ++++++++++---------- route_sql/scenario_package.sql | 258 ++++++++++++++++----------------- 2 files changed, 208 insertions(+), 208 deletions(-) diff --git a/route_sql/get_pool.sql b/route_sql/get_pool.sql index 3422c57..2084920 100644 --- a/route_sql/get_pool.sql +++ b/route_sql/get_pool.sql @@ -1,80 +1,80 @@ -WITH rows AS ( -SELECT - ---------customer info----------------- - bill_cust_descr - ,billto_group - ,ship_cust_descr - ,shipto_group - ,quota_rep_descr - ,director_descr - ,segm - ,mod_chan - ,mod_chansub - ---------product info------------------ - ,majg_descr - ,ming_descr - ,majs_descr - ,mins_descr - ,brand - ,part_family - ,part_group - ,branding - ,color - ,part_descr - ---------dates------------------------- - ,order_season - ,order_month - ,ship_season - ,ship_month - ,request_season - ,request_month - ,promo - ,version - ,iter - --------values------------------------- - ,sum(value_loc) value_loc - ,sum(value_usd) value_usd - ,sum(cost_loc) cost_loc - ,sum(cost_usd) cost_usd - ,sum(units) units -FROM - rlarp.osm_fcpool -WHERE - quota_rep_descr = 'rep_replace' -GROUP BY - ---------customer info----------------- - bill_cust_descr - ,billto_group - ,ship_cust_descr - ,shipto_group - ,quota_rep_descr - ,director_descr - ,segm - ,mod_chan - ,mod_chansub - ---------product info------------------ - ,majg_descr - ,ming_descr - ,majs_descr - ,mins_descr - ,brand - ,part_family - ,part_group - ,branding - ,color - ,part_descr - ---------dates------------------------- - ,order_season - ,order_month - ,ship_season - ,ship_month - ,request_season - ,request_month - ,promo - ,version - ,iter -) -SELECT - json_agg(row_to_json(rows)) x -FROM +WITH rows AS ( +SELECT + ---------customer info----------------- + bill_cust_descr + ,billto_group + ,ship_cust_descr + ,shipto_group + ,quota_rep_descr + ,director_descr + ,segm + ,mod_chan + ,mod_chansub + ---------product info------------------ + ,majg_descr + ,ming_descr + ,majs_descr + ,mins_descr + ,brand + ,part_family + ,part_group + ,branding + ,color + ,part_descr + ---------dates------------------------- + ,order_season + ,order_month + ,ship_season + ,ship_month + ,request_season + ,request_month + ,promo + ,version + ,iter + --------values------------------------- + ,sum(value_loc) value_loc + ,sum(value_usd) value_usd + ,sum(cost_loc) cost_loc + ,sum(cost_usd) cost_usd + ,sum(units) units +FROM + rlarp.osm_fcpool +WHERE + quota_rep_descr = 'rep_replace' +GROUP BY + ---------customer info----------------- + bill_cust_descr + ,billto_group + ,ship_cust_descr + ,shipto_group + ,quota_rep_descr + ,director_descr + ,segm + ,mod_chan + ,mod_chansub + ---------product info------------------ + ,majg_descr + ,ming_descr + ,majs_descr + ,mins_descr + ,brand + ,part_family + ,part_group + ,branding + ,color + ,part_descr + ---------dates------------------------- + ,order_season + ,order_month + ,ship_season + ,ship_month + ,request_season + ,request_month + ,promo + ,version + ,iter +) +SELECT + json_agg(row_to_json(rows)) x +FROM rows \ No newline at end of file diff --git a/route_sql/scenario_package.sql b/route_sql/scenario_package.sql index bd78fe3..bdfa070 100644 --- a/route_sql/scenario_package.sql +++ b/route_sql/scenario_package.sql @@ -1,130 +1,130 @@ ---\timing ---explain (analyze, buffers) -WITH -mseq AS ( - SELECT * FROM - ( - VALUES - ('Jun',1) - ,('Jul',2) - ,('Aug',3) - ,('Sep',4) - ,('Oct',5) - ,('Nov',6) - ,('Dec',7) - ,('Jan',8) - ,('Feb',9) - ,('Mar',10) - ,('Apr',11) - ,('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_fcpool -WHERE - 'where_clause' -GROUP BY - order_season - ,order_month - ,version - ,iter - ,part_descr - ,bill_cust_descr - ,ship_cust_descr -) -,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 = 2019) "2019 qty" - ,SUM(units) FILTER (WHERE order_season = 2020 AND iter = 'copy') "2020 base qty" - ,SUM(units) FILTER (WHERE order_season = 2020 AND iter = 'adjustment') "2020 adj qty" - ,SUM(units) FILTER (WHERE order_season = 2020 AND iter IN ('copy','adjustment')) "2020 tot qty" - ,SUM(value_usd) FILTER (WHERE order_season = 2019) "2019 value_usd" - ,SUM(value_usd) FILTER (WHERE order_season = 2020 AND iter = 'copy') "2020 base value_usd" - ,SUM(value_usd) FILTER (WHERE order_season = 2020 AND iter = 'adjustment') "2020 adj value_usd" - ,SUM(value_usd) FILTER (WHERE order_season = 2020 AND iter IN ('copy','adjustment')) "2020 tot value_usd" - FROM - months - GROUP BY - order_month - ,seq - ORDER BY - seq ASC -) -,mlist AS ( - SELECT - mseq.m order_month - ,"2019 qty" - ,"2020 base qty" - ,"2020 adj qty" - ,"2020 tot qty" - ,"2019 value_usd" - ,"2020 base value_usd" - ,"2020 adj value_usd" - ,"2020 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 -) -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) - ,'base' - ,(SELECT jsonb_agg(row_to_json(base)::jsonb) FROM base) - ,'totals' - ,(SELECT jsonb_agg(row_to_json(totals)::jsonb) FROM totals) +--\timing +--explain (analyze, buffers) +WITH +mseq AS ( + SELECT * FROM + ( + VALUES + ('Jun',1) + ,('Jul',2) + ,('Aug',3) + ,('Sep',4) + ,('Oct',5) + ,('Nov',6) + ,('Dec',7) + ,('Jan',8) + ,('Feb',9) + ,('Mar',10) + ,('Apr',11) + ,('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_fcpool +WHERE + 'where_clause' +GROUP BY + order_season + ,order_month + ,version + ,iter + ,part_descr + ,bill_cust_descr + ,ship_cust_descr +) +,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 = 2019) "2019 qty" + ,SUM(units) FILTER (WHERE order_season = 2020 AND iter = 'copy') "2020 base qty" + ,SUM(units) FILTER (WHERE order_season = 2020 AND iter = 'adjustment') "2020 adj qty" + ,SUM(units) FILTER (WHERE order_season = 2020 AND iter IN ('copy','adjustment')) "2020 tot qty" + ,SUM(value_usd) FILTER (WHERE order_season = 2019) "2019 value_usd" + ,SUM(value_usd) FILTER (WHERE order_season = 2020 AND iter = 'copy') "2020 base value_usd" + ,SUM(value_usd) FILTER (WHERE order_season = 2020 AND iter = 'adjustment') "2020 adj value_usd" + ,SUM(value_usd) FILTER (WHERE order_season = 2020 AND iter IN ('copy','adjustment')) "2020 tot value_usd" + FROM + months + GROUP BY + order_month + ,seq + ORDER BY + seq ASC +) +,mlist AS ( + SELECT + mseq.m order_month + ,"2019 qty" + ,"2020 base qty" + ,"2020 adj qty" + ,"2020 tot qty" + ,"2019 value_usd" + ,"2020 base value_usd" + ,"2020 adj value_usd" + ,"2020 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 +) +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) + ,'base' + ,(SELECT jsonb_agg(row_to_json(base)::jsonb) FROM base) + ,'totals' + ,(SELECT jsonb_agg(row_to_json(totals)::jsonb) FROM totals) ) package \ No newline at end of file