raena_analytics_scripts/redshift/oos_stock_restock.sh

651 lines
25 KiB
Bash

#!/bin/bash
echo -e " \n----------- ACCEPTING NUMBER OF DAYS BEFORE THE RUN DATE FOR WHICH THE REPORT IS TO BE RUN --------------\n"
backDay=$1
echo $backDay
echo -e " \n------------- DATE IN THE REQUIRED FORMAT --------------\n"
reportDate=$(date -d"$backDay day ago" "+%Y-%m-%d")
date
echo 'reportDate'=$reportDate
echo "
--------------------------OOS -------------------------
DROP TABLE IF EXISTS raena_analytics.om_oos_soldout_1;
CREATE TABLE raena_analytics.om_oos_soldout_1 as
SELECT snp_date_time,
sku_code,
inventory
FROM
( SELECT snp_date,
snp_time,
snp_date_time,
sku_code,
inventory,
row_number() over (partition BY sku_code,cast(snp_date_time AS date)
ORDER BY snp_date_time DESC,inventory DESC) AS R
FROM
( SELECT DISTINCT snp_date,
snp_time,
to_timestamp(snp_date || ' ' || snp_time,'YY-MM-DD HH24:MI:SS') +interval'7 hours' AS snp_date_time,
sku_code,
inventory
FROM raena_analytics.inventory_snapshot
where snp_time+interval'7 hours'>='23:30'
)A ) B
WHERE R=1;
DROP TABLE IF EXISTS raena_analytics.om_oos_soldout_2;
CREATE TABLE raena_analytics.om_oos_soldout_2 AS
select *, datediff(day,cast(snp_date_time as date),current_date) as age
FROM raena_analytics.om_oos_soldout_1;
DROP TABLE IF EXISTS raena_analytics.om_oos_soldout_2_med;
CREATE TABLE raena_analytics.om_oos_soldout_2_med AS
SELECT *,
CASE
WHEN age BETWEEN 1 AND 3 THEN '<=3'
WHEN age BETWEEN 4 AND 7 THEN '4-7'
WHEN age BETWEEN 8 AND 15 THEN '8-15'
WHEN age > 15 THEN 'GT 15'
END AS age_group
FROM raena_analytics.om_oos_soldout_2
WHERE age>0;
DROP TABLE IF EXISTS raena_analytics.om_oos_soldout_3;
CREATE TABLE raena_analytics.om_oos_soldout_3 AS
SELECT a.*,
b.inventory AS Maximum_occurred_inventory
FROM raena_analytics.om_oos_soldout_2_med a
INNER JOIN
(SELECT inventory,
age_group,
sku_code
FROM
(SELECT inventory,
age_group,
sku_code,
row_number() over (partition BY age_group,sku_code
ORDER BY Max_inventory DESC) AS R
FROM
(SELECT inventory,
age_group,
sku_code,
count(*) AS Max_inventory
FROM raena_analytics.om_oos_soldout_2_med
GROUP BY inventory,
age_group,
sku_code
ORDER BY 4 DESC,1) A) AA
WHERE R=1
ORDER BY 2,
3) b ON a.sku_code=b.sku_code
AND a.age_group=b.age_group ;
DROP TABLE IF EXISTS raena_analytics.om_oos_soldout_3_med;
CREATE TABLE raena_analytics.om_oos_soldout_3_med AS
SELECT a.*,
b.\"<=3 Maximum_occurred_inventory\",
\"4-7 Maximum_occurred_inventory\",
\"8-15 Maximum_occurred_inventory\",
\"GT 15 Maximum_occurred_inventory\"
FROM raena_analytics.om_oos_soldout_3 a
INNER JOIN
(SELECT DISTINCT sku_code,
sum(CASE WHEN Age_group IN ('<=3') THEN Maximum_occurred_inventory END) AS \"<=3 Maximum_occurred_inventory\",
sum(CASE WHEN Age_group IN ('4-7') THEN Maximum_occurred_inventory END) AS \"4-7 Maximum_occurred_inventory\",
sum(CASE WHEN Age_group IN ('8-15') THEN Maximum_occurred_inventory END) AS \"8-15 Maximum_occurred_inventory\",
sum(CASE WHEN Age_group IN ('GT 15') THEN Maximum_occurred_inventory END)AS \"GT 15 Maximum_occurred_inventory\"
FROM raena_analytics.om_oos_soldout_3
GROUP BY 1
ORDER BY sku_code) b ON a.sku_code=b.sku_code ;
DROP TABLE IF EXISTS raena_analytics.om_oos_soldout_3_med_2;
CREATE TABLE raena_analytics.om_oos_soldout_3_med_2 AS
SELECT a.*,
b.sold_out_fl
FROM raena_analytics.om_oos_soldout_3 a
INNER JOIN
(SELECT sku_code,
sold_out_fl
FROM
(SELECT *,
row_number() over (partition BY sku_code
ORDER BY sold_out_fl) AS R
FROM
(SELECT DISTINCT sku_code,
CASE WHEN ((age=16
OR age=17
OR age=18
OR age=19)
AND inventory=0)
AND (\"8-15 Maximum_occurred_inventory\"=0)
AND \"4-7 Maximum_occurred_inventory\"=0
AND \"<=3 Maximum_occurred_inventory\"=0 THEN '1.GT 15 and sold out'
WHEN (age=8 AND inventory=0)
AND \"4-7 Maximum_occurred_inventory\"=0
AND \"<=3 Maximum_occurred_inventory\"=0 THEN '2.8-15 AND sold OUT'
WHEN ((age=4 OR age=5
OR age=6)
AND inventory=0)
AND \"<=3 Maximum_occurred_inventory\"=0 THEN '3.4-7 and sold out'
WHEN (age=1 AND inventory=0) THEN '4.<=3 and sold out' ELSE '5.stocked' END AS sold_out_fl
FROM raena_analytics.om_oos_soldout_3_med
)A) B
WHERE R=1) b ON a.sku_code=b.sku_code ;
DROP TABLE IF EXISTS raena_analytics.om_oos_soldout_4;
CREATE TABLE raena_analytics.om_oos_soldout_4 AS
SELECT a.*,
b.brand_name,
b.\"EL/PL Flag\", b.give_away,
b.active_status
FROM raena_analytics.om_oos_soldout_3_med_2 a
INNER JOIN
(SELECT DISTINCT b.name AS brand_name,
a.sku,
CASE
WHEN moqremark = 'NOT ORDER GIVE AWAY ITEM' THEN 'Yes'
ELSE 'No'
END give_away,
CASE
WHEN a.is_archived = 'true' THEN 'Permanatly_delisted'
WHEN a.is_delisted = 'true' THEN 'delisted'
WHEN a.is_archived = 'false'
AND a.is_delisted = 'false' THEN 'Active'
END active_status,
CASE
WHEN b.name IN ('HISTOIRE NATURELLE',
'INGRID',
'W DRESSROOM',
'FORENCOS',
'DEWYCEL',
'GLUTANEX',
'BELLFLOWER',
'ONE THING',
'BEAUSTA') THEN 'EL/PL'
ELSE 'NA'
END AS \"EL/PL Flag\"
FROM raena_catalog_management.product a
LEFT JOIN raena_catalog_management.brand b ON a.brand_id=b.id
LEFT JOIN raena_analytics.demand_forecasting_configs c ON a.sku=c.sku) b ON a.sku_code=b.sku ;
DROP TABLE IF EXISTS raena_analytics.om_oos_soldout_5;
CREATE TABLE raena_analytics.om_oos_soldout_5 AS
SELECT a.*,
coalesce(b.sku_type,'Not Moving') AS sku_type,
coalesce(b.new_sku_flag,'No') AS new_sku_flag,
cikarang_runrate,
surabaya_runrate,
semarang_runrate,
medan_runrate,
makassar_runrate,
samarinda_runrate,
total_runrate,
c.gold_price,
d.runrate AS \"90_days_runrate\"
FROM raena_analytics.om_oos_soldout_4 a
LEFT JOIN raena_analytics.demand_forecast_dashboard_final b ON a.sku_code=b.sku
LEFT JOIN
(SELECT DISTINCT sku ,
CASE
WHEN is_slash_price='true' then json_extract_path_text(slashed_tier_price,'bf645e97-8a48-4977-8367-e987489760f9',TRUE)
else json_extract_path_text(tier_price,'bf645e97-8a48-4977-8367-e987489760f9',TRUE)
END AS gold_price
FROM raena_catalog_management.product p) c ON a.sku_code=c.sku
LEFT JOIN
(SELECT sku,
sum(oi.quantity)/count(DISTINCT cast(o.created_at AS date)) AS runrate
FROM raena_order_management.order o
INNER JOIN raena_order_management.order_item oi ON o.id=oi.order_id
WHERE cast(o.created_at AS date)>=cast((CURRENT_DATE-90) AS date)
AND (o.payment_status='Paid' or o.id like 'PL%')
AND cast(o.is_archived AS varchar)='false'
GROUP BY sku) d ON a.sku_code=d.sku ;
DROP TABLE IF EXISTS raena_analytics.om_oos_soldout_6;
CREATE TABLE raena_analytics.om_oos_soldout_6 AS
SELECT DISTINCT cast(a.snp_date_time AS date) AS snp_date_time,
a.sku_code,
\"90_days_runrate\",
a.gold_price,
OOS_days,
a.sold_out_fl,
a.active_status,
a.brand_name,
\"EL/PL Flag\",
a.give_away,
a.sku_type,
a.new_sku_flag,
c.total_runrate,
d.avg_remaining_LM_RV,
d.avg_All_LM_RV,
e.PO_Ordered_quantity
FROM raena_analytics.om_oos_soldout_5 a
INNER JOIN
(SELECT sku_code,
sold_out_fl,
max(CASE WHEN inventory=0
AND sold_out_fl='1.GT 15 and sold out'
AND age>15 THEN age WHEN inventory=0
AND sold_out_fl='2.8-15 and sold out'
AND age BETWEEN 8 AND 15 THEN age WHEN inventory=0
AND sold_out_fl='3.4-7 and sold out'
AND age BETWEEN 4 AND 7 THEN age WHEN inventory=0
AND sold_out_fl='4.<=3 and sold out'
AND age <=3 THEN age END) AS OOS_days
FROM raena_analytics.om_oos_soldout_5
WHERE sold_out_fl NOT LIKE '%stocked'
GROUP BY 1,
2) b ON a.sku_code=b.sku_code
LEFT JOIN raena_analytics.demand_forecast_dashboard_final c ON a.sku_code=c.sku
LEFT JOIN
(SELECT sku,
avg(remaining_shipping_fee)/avg(remaining_payment_amount) AS avg_remaining_LM_RV,
avg(shipping_fee)/avg(payment_amount) AS avg_All_LM_RV
FROM
(SELECT DISTINCT sku,
CASE WHEN (actual_warehouse!=expected_warehouse)
OR expected_warehouse IS NULL
AND payment_amount is NOT NULL
THEN payment_amount END AS remaining_payment_amount,
CASE WHEN (actual_warehouse!=expected_warehouse)
OR expected_warehouse ISNULL
AND payment_amount NOTNULL
THEN \"Actual Shipping Fee\" END AS remaining_shipping_fee,
payment_amount,
\"Actual Shipping Fee\" AS shipping_fee
FROM
(SELECT DISTINCT sku,
actual_warehouse,
expected_warehouse,
A.payment_amount,
CASE WHEN A.sub_order_shipping_id=sb.reference_id AND A.order_id=sb.order_id THEN ((sb.shipping_amount)/(sb.order_weight))*(sb.final_weight)
WHEN A.order_id = D.id AND (A.sub_order_shipping_id= D.id OR A.sub_order_shipping_id IS NULL) THEN D.shipping_amount
WHEN A.sub_order_shipping_id=C.id THEN C.shipping_amount END \"Actual Shipping Fee\"
FROM raena_analytics.rate_sheet_wise_expected_warehouse A
LEFT JOIN raena_order_management.sales_sub_order_shipment C ON A.sub_order_shipping_id=C.id
LEFT JOIN raena_order_management.order D ON A.order_id = D.id
AND (A.sub_order_shipping_id= D.id
OR A.sub_order_shipping_id IS NULL)
LEFT JOIN raena_analytics.OM_Logistic_final_shipping_base sb ON A.sub_order_shipping_id=sb.reference_id
AND A.order_id=sb.order_id
WHERE A.created_date>=(CURRENT_DATE-90)
AND A.is_campaign='false')AAA) AA
WHERE payment_amount!=0
GROUP BY 1) d ON a.sku_code=d.sku
LEFT JOIN
(SELECT raena_code sku,
coalesce(sum(CASE WHEN warehouse_id = 'CGK WHS' THEN COALESCE(quantity,0) END),0) +
coalesce(sum(CASE WHEN warehouse_id = 'Makassar WHS' THEN COALESCE(quantity,0) END),0) +
coalesce(sum(CASE WHEN warehouse_id = 'Medan WHS' THEN COALESCE(quantity,0) END),0) +
coalesce(sum(CASE WHEN warehouse_id = 'Samarinda WHS' THEN COALESCE(quantity,0) END),0) +
coalesce(sum(CASE WHEN warehouse_id = 'Semarang WHS' THEN COALESCE(quantity,0) END),0) +
coalesce(sum(CASE WHEN warehouse_id = 'Surabaya WHS' THEN COALESCE(quantity,0) END),0) PO_Ordered_quantity
FROM raena_erp_management.inbound_order A
LEFT JOIN raena_erp_management.inbound_order_sku B ON A.id = B.\"orderIdId\"
WHERE cast(expected_arrival_date AS date) > CURRENT_DATE -1
AND received_time IS NULL
GROUP BY raena_code) e ON a.sku_code=e.sku;
-------------------restock
DROP TABLE IF EXISTS raena_analytics.om_oos_restock_1;
CREATE TABLE raena_analytics.om_oos_restock_1 AS
SELECT report_date,
a.sku,
overall_qty_required_per_day AS restock,
sku_type,
brand_name,
give_away,
new_sku_flag,
active_status,
coalesce(cikarang_project_quantity_to_order,0) AS cikarang_project_quantity_to_order,
coalesce(surabaya_project_quantity_to_order,0) AS surabaya_project_quantity_to_order,
coalesce(semarang_project_quantity_to_order,0) AS semarang_project_quantity_to_order,
coalesce(medan_project_quantity_to_order,0) AS medan_project_quantity_to_order,
coalesce(makassar_project_quantity_to_order,0) AS makassar_project_quantity_to_order,
coalesce(semarandi_project_quantity_to_order,0) AS semarandi_project_quantity_to_order ,
CASE
WHEN brand_name IN ('HISTOIRE NATURELLE',
'INGRID',
'W DRESSROOM',
'FORENCOS',
'DEWYCEL',
'GLUTANEX',
'BELLFLOWER',
'ONE THING',
'BEAUSTA') THEN 'EL/PL'
ELSE 'NA'
END AS \"EL/PL Flag\",
datediff(day,cast(report_date as date),current_date) as age,
c.gold_price
FROM raena_analytics.OM_OOS_Base a
LEFT JOIN
(SELECT DISTINCT sku ,
CASE
WHEN is_slash_price='true' then json_extract_path_text(slashed_tier_price,'bf645e97-8a48-4977-8367-e987489760f9',TRUE)
else json_extract_path_text(tier_price,'bf645e97-8a48-4977-8367-e987489760f9',TRUE)
END AS gold_price
FROM raena_catalog_management.product p) c ON a.sku=c.sku;
DROP TABLE IF EXISTS raena_analytics.om_oos_restock_1_med;
CREATE TABLE raena_analytics.om_oos_restock_1_med AS
SELECT *
FROM raena_analytics.om_oos_restock_1 unpivot (cnt
FOR warehouse IN
(cikarang_project_quantity_to_order,
surabaya_project_quantity_to_order,
semarang_project_quantity_to_order,
medan_project_quantity_to_order,
makassar_project_quantity_to_order,
semarandi_project_quantity_to_order));
DROP TABLE IF EXISTS raena_analytics.om_oos_restock_2;
CREATE TABLE raena_analytics.om_oos_restock_2 AS
SELECT *,
CASE
WHEN age BETWEEN 1 AND 3 THEN '<=3'
WHEN age BETWEEN 4 AND 7 THEN '4-7'
WHEN age BETWEEN 8 AND 15 THEN '8-15'
WHEN age > 15 THEN 'GT 15'
END AS age_group
FROM raena_analytics.om_oos_restock_1_med
WHERE age>0;
DROP TABLE IF EXISTS raena_analytics.om_oos_restock_3;
CREATE TABLE raena_analytics.om_oos_restock_3 AS
SELECT a.*,
b.restock AS Maximum_occurred_inventory
FROM raena_analytics.om_oos_restock_2 a
INNER JOIN
(SELECT restock,
age_group,
sku,
warehouse
FROM
(SELECT restock,
age_group,
warehouse,
sku,
row_number() over (partition BY age_group,warehouse,sku
ORDER BY Max_inventory DESC) AS R
FROM
(SELECT cnt AS restock,
age_group,
warehouse,
sku,
count(*) AS Max_inventory
FROM raena_analytics.om_oos_restock_2
GROUP BY cnt,
age_group,
warehouse,
sku
ORDER BY 5 DESC,1) A) B
WHERE R=1
ORDER BY 2,
3) b ON a.sku=b.sku
AND a.age_group=b.age_group
AND a.warehouse=b.warehouse;
DROP TABLE IF EXISTS raena_analytics.om_oos_restock_4;
CREATE TABLE raena_analytics.om_oos_restock_4 AS
SELECT a.*,
b.\"<=3 Maximum_occurred_inventory\",
\"4-7 Maximum_occurred_inventory\",
\"8-15 Maximum_occurred_inventory\",
\"GT 15 Maximum_occurred_inventory\"
FROM raena_analytics.om_oos_restock_3 a
INNER JOIN
( SELECT DISTINCT sku,
warehouse,
sum(CASE WHEN Age_group IN ('<=3') THEN Maximum_occurred_inventory END)AS \"<=3 Maximum_occurred_inventory\",
sum(CASE WHEN Age_group IN ('4-7') THEN Maximum_occurred_inventory END) AS \"4-7 Maximum_occurred_inventory\",
sum(CASE WHEN Age_group IN ('8-15') THEN Maximum_occurred_inventory END) AS \"8-15 Maximum_occurred_inventory\",
sum(CASE WHEN Age_group IN ('GT 15') THEN Maximum_occurred_inventory END)AS \"GT 15 Maximum_occurred_inventory\"
FROM raena_analytics.om_oos_restock_3
GROUP BY 1,
2
ORDER BY sku ) b ON a.sku=b.sku
AND a.warehouse=b.warehouse;
drop table if exists raena_analytics.om_oos_restock_4_stage1;
create table raena_analytics.om_oos_restock_4_stage1
as
SELECT sku,
sold_out_fl,
warehouse
FROM
( SELECT *,
row_number() over (partition BY sku
ORDER BY sold_out_fl) AS R
FROM
( SELECT DISTINCT sku,
warehouse,
CASE WHEN ((age=16)
AND restock=0)
AND (\"8-15 Maximum_occurred_inventory\"=0)
AND \"4-7 Maximum_occurred_inventory\"=0
AND \"<=3 Maximum_occurred_inventory\"=0
THEN '1.GT 15 and sold out'
WHEN (age=8 AND restock=0)
AND \"4-7 Maximum_occurred_inventory\"=0
AND \"<=3 Maximum_occurred_inventory\"=0
THEN '2.8-15 AND s OLD OUT'
WHEN ((age=4) AND restock=0)
AND \"<=3 Maximum_occurred_inventory\"=0
THEN '3.4-7 and sold out'
WHEN (age=1 AND restock=0)
THEN '4.<=3 and sold out'
ELSE '5.stocked' END AS sold_out_fl
FROM raena_analytics.om_oos_restock_4
)A )B
WHERE R=1 ;
drop table if exists raena_analytics.om_oos_restock_4_stage2;
create table raena_analytics.om_oos_restock_4_stage2
as
SELECT sku,
sum(quantity)/count(DISTINCT cast(transaction_date AS date)) AS runrate
FROM raena_analytics.gm_dashboard
WHERE cast(transaction_date AS date)>=cast((CURRENT_DATE-90) AS date)
GROUP BY sku;
DROP TABLE IF EXISTS raena_analytics.om_oos_restock_5;
CREATE TABLE raena_analytics.om_oos_restock_5 AS
SELECT a.*,
b.sold_out_fl,
c.runrate AS \"90_days_runrate\"
FROM raena_analytics.om_oos_restock_4 a
INNER JOIN raena_analytics.om_oos_restock_4_stage1 b ON a.sku=b.sku
AND a.warehouse=b.warehouse
LEFT JOIN raena_analytics.om_oos_restock_4_stage2 c ON a.sku=c.sku;
DROP TABLE IF EXISTS raena_analytics.weight_sku_table;
CREATE TABLE raena_analytics.weight_sku_table AS
SELECT sku,
CASE
WHEN weight>=volume_weight THEN weight
ELSE volume_weight
END weight
FROM
(SELECT a.sku,
weight,
(height*width*LENGTH)/6000 AS volume_weight
FROM raena_catalog_management.product a
WHERE CLASS<>'Bundle') A;
drop table if exists raena_analytics.om_oos_restock_5_stage1;
CREATE TABLE raena_analytics.om_oos_restock_5_stage1 AS
SELECT sku,
sum(payment_amount)payment_amount,
sum(quantity)quantity,
sub_order_shipping_id,
sum(shipping_amount)shipping_amount
FROM raena_analytics.rate_sheet_wise_expected_warehouse
WHERE created_date>=(CURRENT_DATE-90)
AND is_campaign='false'
group by 1,4;
drop table if exists raena_analytics.om_oos_restock_5_stage2;
CREATE TABLE raena_analytics.om_oos_restock_5_stage2 AS
SELECT DISTINCT A.sku,
A.payment_amount,
A.quantity,
A.sub_order_shipping_id,
A.shipping_amount \"Actual Shipping Fee\",
DD.Expected_shipping_fee,
jsf.expected_JTR_shipping_fee
FROM
raena_analytics.om_oos_restock_5_stage1 A
LEFT JOIN
(SELECT DISTINCT sub_order_shipping_id,
Expected_shipping_fee
FROM raena_analytics.rate_sheet_wise_expected_warehouse_expected_shipping_final
WHERE Expected_shipping_fee IS NOT NULL ) DD ON A.sub_order_shipping_id=DD.sub_order_shipping_id
LEFT join
(SELECT sub_order_shipping_id ,
expected_JTR_shipping_fee
FROM raena_analytics.om_shipment_jtr_shipping_fee_base_11
WHERE expected_JTR_shipping_fee IS NOT NULL) jsf ON A.sub_order_shipping_id=jsf.sub_order_shipping_id;
DROP TABLE IF EXISTS raena_analytics.om_shipping_fee_sku_base_stage2;
CREATE TABLE raena_analytics.om_shipping_fee_sku_base_stage2 AS
SELECT A.*,
B.weight*Quantity sku_weight,
CASE
WHEN (B.weight*Quantity)<1.3 THEN 1
WHEN (B.weight*Quantity)>=1.3
AND (ABS((B.weight*Quantity)) - FLOOR(ABS((B.weight*Quantity)))) BETWEEN 0.3 AND 0.999999 THEN FLOOR((B.weight*Quantity))+1
ELSE FLOOR((B.weight*Quantity))
END AS final_weight
FROM
( SELECT sku,
payment_amount,
quantity,
sub_order_shipping_id,
coalesce(expected_JTR_shipping_fee,Expected_shipping_fee,\"Actual Shipping Fee\") AS Expected_shipping_fee,
\"Actual Shipping Fee\"
from raena_analytics.om_oos_restock_5_stage2) A
LEFT JOIN raena_analytics.weight_sku_table B ON A.sku = B.sku ;
DROP TABLE IF EXISTS raena_analytics.om_shipping_fee_sku_base_stage3;
CREATE TABLE raena_analytics.om_shipping_fee_sku_base_stage3 AS
SELECT *,
(sku_weight*\"Actual Shipping Fee\")/sum(sku_weight) over(partition BY sub_order_shipping_id) new_shipment_amount,
(sku_weight*Expected_shipping_fee)/sum(sku_weight) over(partition BY sub_order_shipping_id) new_expected_shipment_amount
FROM raena_analytics.om_shipping_fee_sku_base_stage2;
DROP TABLE IF EXISTS raena_analytics.om_oos_restock_6;
CREATE TABLE raena_analytics.om_oos_restock_6 AS
SELECT DISTINCT a.report_date,
a.sku,
a.sku_type,
a.brand_name,
a.give_away,
a.new_sku_flag,
a.active_status,
\"EL/PL Flag\",
a.age,
a.gold_price,
a.cnt,
a.age_group,
a.sold_out_fl,
\"90_days_runrate\",
b.restock_days,
c.total_runrate,
d.avg_remaining_LM_RV,
d.avg_All_LM_RV
FROM raena_analytics.om_oos_restock_5 a
INNER JOIN
(SELECT sku,
sold_out_fl,
max(CASE WHEN restock=0
AND sold_out_fl='1.GT 15 and sold out'
AND age>15 THEN age WHEN restock=0
AND sold_out_fl='2.8-15 and sold out'
AND age BETWEEN 8 AND 15 THEN age WHEN restock=0
AND sold_out_fl='3.4-7 and sold out'
AND age BETWEEN 4 AND 7 THEN age WHEN restock=0
AND sold_out_fl='4.<=3 and sold out'
AND age <=3 THEN age END) AS restock_days
FROM raena_analytics.om_oos_restock_5
WHERE sold_out_fl NOT LIKE '%stocked'
GROUP BY 1,
2) b ON a.sku=b.sku
LEFT JOIN raena_analytics.demand_forecast_dashboard_final c ON a.sku=c.sku
LEFT JOIN
(SELECT sku,
avg(shipping_fee)/avg(payment_amount) AS avg_remaining_LM_RV,
avg(new_expected_shipment_amount)/avg(payment_amount) AS avg_All_LM_RV
FROM
(SELECT sku, new_expected_shipment_amount, payment_amount,\"Actual Shipping Fee\" AS shipping_fee
FROM
(SELECT sku,
(payment_amount/quantity) AS payment_amount,
(new_shipment_amount/quantity) AS \"Actual Shipping Fee\", (new_expected_shipment_amount/quantity) AS new_expected_shipment_amount
FROM raena_analytics.om_shipping_fee_sku_base_stage3
)A) B
WHERE payment_amount!=0
GROUP BY 1) d ON a.sku=d.sku;
" > /home/ec2-user/cronjob/redshift/sql_code/oos_restock_etl.sql
psql "host=redshift-cluster-1.cdqj58hfx4p7.ap-southeast-1.redshift.amazonaws.com user=dbadmin dbname=analytics port=5439 password=5qCif6eyY3Kmg4z" -f /home/ec2-user/cronjob/redshift/sql_code/oos_restock_etl.sql