forecast_api/build/build_baseline_from_FAnalysis.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

796 lines
32 KiB
SQL

-- Connection: usmidsql01.FAnalysis
/*
*******************************************************************************************************************************************
** Phil Runninger, 4/27/2023 *************************************************************************************************************
**
** Here is how you use this script. This procedure is only temporary, as the entire
** system will be rewritten for the 2025 season.
**
** 1. In SSMS...
** a. Turn on the option: Query Results, Sql Server, Results to Grid, Include column headers....
** b. Connect to usmidsql01.
** c. Run this script in the FAnalysis database.
** d. Right-click in the results grid, and choose Save Results As...
** 2. In a proper text editor, aka Neovim, remove all instances of NULL from the exported file, leaving nothing between the commas.
** 3. In DBeaver,
** a. Log into usmidsap01
** b. Navigate to the ubm.rlarp.osm_pool table
** c. Right-click, and choose Import Data.
** d. Follow the self-explanatory steps in the wizard. Make sure to choose the option to empty the table first.
** e. Verify the import worked correctly.
** f. Run the following statements to finish setting up the system.
** DELETE FROM rlarp.osm_log WHERE id > 1;
** ALTER SEQUENCE rlarp.osm_log_id_seq RESTART 1;
**
*******************************************************************************************************************************************
*******************************************************************************************************************************************
Baseline Data New Method:
Forecasting on Orders Basis
1 -- Pull 2023 Sales & Volumes + 2023 Promised Sales & Volumes
2 - Backout 2024 Open Orders --
3 -- Sum 1 and 2, Group By ShiptoGroup, Partgroup
4 - Pull 2019 Orders Group By ShipToGroup, Partgroup, OrderMonth
5 - Map 3 (total) to 4 (by order month)
ShipTo and Partgroup in both
* Shipto and Partgroup does not exist in 2019 --> Subtract from 2023 Ship 90
Exists in 2019, does not exists in 2023 -- > Ignore
On the Orders Worksheet
Show 2019 Orders as Reference
Rollup - As part of process.
*/
----------------------------------------------------------------------
--BASE DATA VALUES RECAST WITH Last Price Paid instead of Spot Price
---------------------------------------------------------------------
SELECT * INTO #BASE_DATA
FROM
( SELECT
[Bill-To] AS bill_cust_descr
,[Bill-To Group] AS billto_group
,[Ship-To] AS ship_cust_descr
,[Ship-To Group] AS shipto_group
,CASE WHEN [Quota Rep] LIKE '[0-9][0-9][0-9][0-9][0-9] -%' THEN LEFT([Quota Rep],5) ELSE NULL END AS [dsm]
,CASE WHEN [Quota Rep] LIKE '[0-9][0-9][0-9][0-9][0-9] -%' THEN SUBSTRING(RTRIM([Quota Rep]), 9, LEN([Quota Rep])-8) ELSE LTRIM(RTRIM([Quota Rep])) END AS [quota_rep_descr]
,[Director] AS [director]
,[Segment] AS [segm]
,CASE WHEN [Major Group] LIKE '610%' THEN 'Fiber' ELSE 'Plastic' END [substance]
,[Channel] AS [chan]
,[Channel Sub] AS [chansub]
,[Channel - Retail] AS [chan_retail]
,[Part Code] AS [part]
,[Part Group Descr] AS [part_descr]
,[Part Group] AS [part_group]
,[Branding Flag] AS [branding]
,LEFT([Major Group],5) + ' ' + [Major Group] AS [majg_descr]
,LEFT([Minor Group],5) + ' ' + [Minor Group] AS [ming_descr]
,LEFT([Major Sales Group],5) + ' ' + [Major Sales Group] AS [majs_descr]
,LEFT([Minor Sales Group],5) + ' ' + [Minor Sales Group] AS [mins_descr]
,[Order Date] AS [order_date]
,[Order Season] AS [order_season]
,[Order Month] AS [order_month]
,[Ship Date] AS [ship_date]
,[Ship Season] AS [ship_season]
,[Ship Month] AS [ship_month]
,[Request Date] AS [request_date]
,[Request Season] AS [request_season]
,[Request Month] AS [request_month]
,[Promo Code] AS [promo]
,[Financial Statement Line] as [fs_line]
,[Inventory Currency] as [r_currency]
,[Order Currency] as [c_currency]
,PRICE.LPP_loc * BASE.Units AS [value_loc]
,PRICE.LPP_USD * BASE.Units AS [value_usd]
,[Standard Cost Local - Historic] AS [cost_loc]
,[Std Cost USD - Historic] AS [cost_usd]
,[Units] AS [units]
,[Pounds] AS [pounds]
,'b24' AS [version]
,'copy' AS [iter]
,1 AS [logid]
,'baseline' AS [tag]
,'don''t undo' AS [comment]
,[Promise Month] AS [Promise Month]
,[Data Source] AS [Data Source]
,[Order Status] AS [Order Status]
,[Promise Season] AS [Promise Season]
FROM [FAnalysis].[RLARP].[osm_stack_pretty_wSTATUS] AS BASE
LEFT OUTER JOIN
(
SELECT shipto_group, [part_descr], /*[Order Number], */ [price_loc] AS [LPP_loc], [price_USD] AS [LPP_USD]
FROM
( SELECT
ROW_NUMBER() OVER (PARTITION BY [Ship-To Group], [Part Code Descr] ORDER BY [Order Date] DESC, [Order Number] DESC) AS LPP_RANK
-- ,[Order Date] AS [Order Date]
-- ,[Order Number] AS [Order Number]
,[Ship-To Group] AS shipto_group
,[Part Code Descr] AS [part_descr]
-- ,[value local] AS [value_loc]
-- ,[value usd] AS [value_usd]
-- ,[Units] AS [units]
,[Value Local] / NULLIF([Units],0) AS [price_loc]
,[Value USD] / NULLIF([Units],0) AS [price_USD]
FROM [FAnalysis].[RLARP].[osm_stack_pretty_wSTATUS]
WHERE
(
([Data Source] = 'Actual' AND [Order Status] = 'Open - Current' AND [Promise Season] >= 2023) OR
([Data Source] = 'Actual' AND [Ship Season] = 2023)
) AND
[Ship-To] IS NOT NULL AND
[Ship-To Group] IS NOT NULL AND
[Order Date] IS NOT NULL
--ORDER BY [shipto_group], [part_descr], LPP_RANK ASC
) AS LPP_RESULT
WHERE LPP_RESULT.LPP_RANK = 1
) PRICE
ON BASE.[Ship-To Group] = PRICE.shipto_group AND
BASE.[Part Code Descr] = PRICE.part_descr
WHERE
(
(BASE.[Data Source] = 'Actual' AND BASE.[Order Status] = 'Open - Current' AND BASE.[Promise Season] >= 2023) OR
(BASE.[Data Source] = 'Actual' AND BASE.[Ship Season] = 2023)
) AND
BASE.[Ship-To] IS NOT NULL AND
BASE.[Ship-To Group] IS NOT NULL
) AS A
CREATE CLUSTERED INDEX IDX_CBASE_DATA_STG ON #BASE_DATA(shipto_group)
CREATE INDEX IDX_CFYBASE_DATA_PG ON #BASE_DATA(part_group)
/* Backout orders that already have been placed for FY2024 from the Order Forecast Baseline */
UPDATE #BASE_DATA SET
[value_loc] = -1 * [value_loc]
,[value_usd] = -1 * [value_usd]
,[cost_loc] = -1 * [cost_loc]
,[cost_usd] = -1 * [cost_usd]
,[units] = -1 * [Units]
,[pounds] = -1 * [Pounds]
WHERE [Data Source] = 'Actual' AND [Order Status] = 'Open - Current' AND [Promise Season] > 2023
----------------------------------------------------------------------------------------------------
--CREATE TEMP TABLES: * Shipto and Partgroup does not exist in 2019 --> Subtract from 2023 Ship 90
--SELECT #BASE_DATA. FROM #BASE_DATA
----------------------------------------------------------------------------------------------------
SELECT * INTO #FY2023 FROM
( SELECT
[shipto_group]
,[part_group]
,[ship_month]
,[value_loc]
,[value_usd]
,[cost_loc]
,[cost_usd]
,[units]
,[pounds]
,[Promise Month]
,CASE
WHEN A.ship_month IS NULL THEN
CASE
WHEN CAST(LEFT(A.[Promise Month],2) AS INT) - 3 < 1 THEN CAST(LEFT(A.[Promise Month],2) AS INT) + 9
ELSE CAST(LEFT(A.[Promise Month],2) AS INT) - 3
END --2023 Promised, Not Shipped
ELSE
CASE
WHEN CAST(LEFT(A.ship_month,2) AS INT) - 3 < 1 THEN CAST(LEFT(A.ship_month,2) AS INT) + 9
ELSE CAST(LEFT(A.ship_month,2) AS INT) - 3
END
END AS order_month_idx
FROM
( SELECT
shipto_group
,[part_group]
,[ship_month]
,SUM([value_loc]) AS [value_loc]
,SUM([value_usd]) AS [value_usd]
,SUM([cost_loc]) AS [cost_loc]
,SUM([cost_usd]) AS [cost_usd]
,SUM([units]) AS [units]
,SUM([pounds]) AS [pounds]
,MAX([Promise Month]) AS [Promise Month]
FROM #BASE_DATA
WHERE
(
([Data Source] = 'Actual' AND [ship_season] = 2023) OR
([Data Source] = 'Actual' AND [Order Status] = 'Open - Current' AND [Promise Season] = 2023)
) AND
[shipto_group] IS NOT NULL AND
[part_group] <> ''
GROUP BY [shipto_group], [part_group], [ship_month]
) AS A
) AS FY23
CREATE CLUSTERED INDEX IDX_CFY2023_STG ON #FY2023(shipto_group)
CREATE INDEX IDX_CFY2023_PG ON #FY2023(part_group)
SELECT * INTO #FY2019 FROM
( SELECT
[Ship-To Group] AS shipto_group
,[Part Group] AS [part_group]
,MAX([Order Month]) AS [order_month]
FROM [FAnalysis].[RLARP].[osm_stack_pretty_wSTATUS]
WHERE
[Data Source] = 'Actual' AND
[Order Season] = 2019 AND
[Ship-To Group] IS NOT NULL AND
[part group] <> ''
GROUP BY [Ship-To Group], [Part Group]
) AS FY19
CREATE CLUSTERED INDEX IDX_CFY2019_STG ON #FY2019(shipto_group)
CREATE INDEX IDX_CFY2019_PG ON #FY2019(part_group)
------------------------
-- BEGIN MASTER QUERY
-------------------------
SELECT
CASE
WHEN DETAIL.[ship_season] IS NULL THEN CAST(DETAIL.[promise_season] % 100 AS varchar) + LEFT(DETAIL.[promise_month], 2)
ELSE CAST(DETAIL.[ship_season] % 100 AS varchar) + LEFT(DETAIL.[ship_month], 2)
END AS [fspr]
,NULL as [plnt]
,DETAIL.[promo]
,NULL as [terms]
,DETAIL.bill_cust_descr
,DETAIL.ship_cust_descr
,DETAIL.[dsm]
,DETAIL.[quota_rep_descr]
,DETAIL.[director]
,DETAIL.billto_group
,DETAIL.shipto_group
,DETAIL.[chan]
,DETAIL.[chansub]
,DETAIL.[chan_retail]
,DETAIL.[part]
,DETAIL.[part_descr]
,DETAIL.[part_group]
,DETAIL.[branding]
,DETAIL.[majg_descr]
,DETAIL.[ming_descr]
,DETAIL.[majs_descr]
,DETAIL.[mins_descr]
,DETAIL.[segm]
,DETAIL.[substance]
,DETAIL.[fs_line]
,DETAIL.[r_currency]
,DETAIL.[value_usd]/nullif(DETAIL.[value_loc],0) as [r_rate]
,DETAIL.[c_currency]
,DETAIL.[cost_usd]/nullif(DETAIL.[cost_loc],0) as [c_rate]
,ROUND(DETAIL.[Units] * MAPPED.Distribution_Factor,0) AS [units]
,DETAIL.[value_loc] * MAPPED.Distribution_Factor AS [value_loc]
,DETAIL.[value_usd] * MAPPED.Distribution_Factor AS [value_usd]
,DETAIL.[cost_loc] * MAPPED.Distribution_Factor AS [cost_loc]
,DETAIL.[cost_usd] * MAPPED.Distribution_Factor AS [cost_usd]
,'CLOSED' as [calc_status]
,'SHIPMENT' as [flag]
,DETAIL.[order_date]
,MAPPED.[order_month]
,2024 AS [order_season]
,DETAIL.[request_date]
,DETAIL.[request_month]
,DETAIL.[request_season]
,DETAIL.[ship_date]
,DETAIL.[ship_month]
,DETAIL.[ship_season]
,[version]
,'copy' AS [iter] -- {'copy'--> baseline data, 'actuals' --> reference data}
,[logid]
,[tag]
,[comment]
,'build_pool' as [module]
,DETAIL.[Pounds] * MAPPED.Distribution_Factor AS [pounds]
FROM
( SELECT
FY23_SALES.shipto_group
,FY23_SALES.part_group
,FY19_ORDERS.order_month AS order_month
,FY23_SALES.value_loc * FY19_ORDERS.Distribution_Factor AS value_loc
,FY23_SALES.value_usd * FY19_ORDERS.Distribution_Factor AS value_usd
,FY23_SALES.cost_loc * FY19_ORDERS.Distribution_Factor AS cost_loc
,FY23_SALES.cost_usd * FY19_ORDERS.Distribution_Factor AS cost_usd
,FY23_SALES.units * FY19_ORDERS.Distribution_Factor AS units
,FY23_SALES.pounds * FY19_ORDERS.Distribution_Factor AS pounds
,FY19_ORDERS.Distribution_Factor AS Distribution_Factor
FROM
( SELECT
shipto_group
,[part_group]
,SUM([value_loc]) AS [value_loc]
,SUM([value_usd]) AS [value_usd]
,SUM([cost_loc]) AS [cost_loc]
,SUM([cost_usd]) AS [cost_usd]
,SUM([units]) AS [units]
,SUM([pounds]) AS [pounds]
FROM
( SELECT /* SHIPPED IN 2023 */
bill_cust_descr
,billto_group
,ship_cust_descr
,[shipto_group]
,[quota_rep_descr]
,[director]
,[segm]
,[substance]
,[chan]
,[chansub]
,[part_descr]
,[part_group]
,[branding]
,[majg_descr]
,[ming_descr]
,[majs_descr]
,[mins_descr]
,[order_season]
,[order_month]
,[ship_date]
,[ship_season]
,[ship_month]
,[request_season]
,[request_month]
,[promo]
,[value_loc]
,[value_usd]
,[cost_loc]
,[cost_usd]
,[units]
,[pounds]
,[version]
,[iter]
,[logid]
,[tag]
,[comment]
FROM #BASE_DATA
WHERE [Data Source] = 'Actual' AND [ship_season] = 2023
UNION ALL
SELECT /* OPEN Promised 2023*/
bill_cust_descr
,billto_group
,ship_cust_descr
,shipto_group
,[quota_rep_descr]
,[director]
,[segm]
,[substance]
,[chan]
,[chansub]
,[part_descr]
,[part_group]
,[branding]
,[majg_descr]
,[ming_descr]
,[majs_descr]
,[mins_descr]
,[order_season]
,[order_month]
,[ship_date]
,[ship_season]
,[ship_month]
,[request_season]
,[request_month]
,[promo]
,[value_loc]
,[value_usd]
,[cost_loc]
,[cost_usd]
,[units]
,[pounds]
,[version]
,[iter]
,[logid]
,[tag]
,[comment]
FROM #BASE_DATA
WHERE [Data Source] = 'Actual' AND [Order Status] = 'Open - Current' AND [Promise Season] = 2023
UNION ALL
SELECT /* OPEN 2024 AND LATER */
bill_cust_descr
,billto_group
,ship_cust_descr
,shipto_group
,[quota_rep_descr]
,[director]
,[segm]
,[substance]
,[chan]
,[chansub]
,[part_descr]
,[part_group]
,[branding]
,[majg_descr]
,[ming_descr]
,[majs_descr]
,[mins_descr]
,[order_season]
,[order_month]
,[ship_date]
,[ship_season]
,[ship_month]
,[request_season]
,[request_month]
,[promo]
,[value_loc] AS [value_loc] /* These values are negative in #BASE_DATA to backout order that already have been placed for FY2024 */
,[value_usd] AS [value_usd]
,[cost_loc] AS [cost_loc]
,[cost_usd] AS [cost_usd]
,[Units] AS [units]
,[Pounds] AS [pounds]
,[version]
,[iter]
,[logid]
,[tag]
,[comment]
FROM #BASE_DATA
WHERE [Data Source] = 'Actual' AND [Order Status] = 'Open - Current' AND [Promise Season] > 2023
) AS A
WHERE part_group <>'' AND shipto_group IS NOT NULL
GROUP BY A.shipto_group, A.part_group
) AS FY23_SALES
LEFT OUTER JOIN
( SELECT * /* 4 - Pull 2019 Orders Group By ShipToGroup, Partgroup, OrderMonth Distribution */
FROM
( SELECT
[shipto_group]
,[part_group]
,[order_month]
,SUM([value_loc]) AS [value_loc]
,SUM([value_usd]) AS [value_usd]
,SUM([cost_loc]) AS [cost_loc]
,SUM([cost_usd]) AS [cost_usd]
,SUM([units]) AS [units]
,SUM([pounds]) AS [pounds]
,SUM([Distribution_Factor]) AS [Distribution_Factor]
FROM
( SELECT /* 2019 Orders*/
CASE
WHEN SUM([units]) OVER (Partition by [Ship-To Group], [Part Group]) <> 0 THEN [units] / SUM([units]) OVER (Partition by [Ship-To Group], [Part Group])
ELSE NULL
END AS [Distribution_Factor]
,[Bill-To] AS bill_cust_descr
,[Bill-To Group] AS billto_group
,[Ship-To] AS ship_cust_descr
,[Ship-To Group] AS shipto_group
,CASE WHEN Right(Left([Quota Rep], 7), 1) = '-' THEN RIGHT(LTRIM(RTRIM([Quota Rep])), Len([Quota Rep]) - 7) ELSE LTRIM(RTRIM([Quota Rep])) END AS [quota_rep_descr]
,[Director] AS [director]
,[Segment] AS [segm]
,CASE WHEN [Major Group] LIKE '610%' THEN 'Fiber' ELSE 'Plastic' END [substance]
,[Channel] AS [chan]
,[Channel Sub] AS [chansub]
,[Part Group Descr] AS [part_descr]
,[Part Group] AS [part_group]
,[Branding Flag] AS [branding]
,LEFT([Major Group],5) + ' ' + [Major Group] AS [majg_descr]
,LEFT([Minor Group],5) + ' ' + [Minor Group] AS [ming_descr]
,LEFT([Major Sales Group],5) + ' ' + [Major Sales Group] AS [majs_descr]
,LEFT([Minor Sales Group],5) + ' ' + [Minor Sales Group] AS [mins_descr]
,[Order Season] AS [order_season]
,[Order Month] AS [order_month]
,[Ship Season] AS [ship_season]
,[Ship Month] AS [ship_month]
,[Request Season] AS [request_season]
,[Request Month] AS [request_month]
,[Promo Code] AS [promo]
,[value local] AS [value_loc]
,[value usd] AS [value_usd]
,[Standard Cost Local - Historic] AS [cost_loc]
,[Std Cost USD - Historic] AS [cost_usd]
,[Units] AS [units]
,[Pounds] AS [pounds]
,'b24' AS [version]
,'copy' AS [iter]
,1 AS [logid]
,'baseline' AS [tag]
,'don''t undo' AS [comment]
FROM [FAnalysis].[RLARP].[osm_stack_pretty_wSTATUS]
WHERE [Data Source] = 'Actual' AND [Order Season] = 2019
) AS B
GROUP BY B.shipto_group, B.part_group, B.order_month
) AS C
--ORDER BY shipto_group, part_group, order_month
) AS FY19_ORDERS
ON FY23_SALES.shipto_group = FY19_ORDERS.shipto_group AND FY23_SALES.part_group = FY19_ORDERS.part_group
WHERE FY19_ORDERS.Order_month is NOT NULL
--ORDER BY part_group ASC, order_month ASC
UNION ALL
SELECT
C.shipto_group
,C.part_group
,D.order_month
,C.value_loc AS value_loc
,C.value_usd AS value_usd
,C.cost_loc AS cost_loc
,C.cost_usd AS cost_usd
,C.units AS units
,C.pounds AS pounds
--,1 AS Distribution_Factor
--,CASE WHEN SUM(C.[units]) OVER (Partition by [C.shipto_group], [C.part_group]) <> 0 THEN C.[units] / SUM(C.[units]) OVER (Partition by [C.shipto_group], [C.part_group]) ELSE NULL END AS [Distribution_Factor]
,C.Distribution_Factor AS Distribution_Factor
FROM
( SELECT
A.shipto_group
,A.part_group
,A.order_month_idx
,A.value_loc AS value_loc
,A.value_usd AS value_usd
,A.cost_loc AS cost_loc
,A.cost_usd AS cost_usd
,A.units AS units
,A.pounds AS pounds
,CASE
WHEN SUM(A.[units]) OVER (Partition by A.[shipto_group], A.[part_group]) <> 0 THEN A.[units] / SUM(A.[units]) OVER (Partition by A.[shipto_group], A.[part_group])
ELSE NULL
END AS [Distribution_Factor]
FROM #FY2023 A
LEFT OUTER JOIN #FY2019 B
ON A.shipto_group = B.shipto_group AND A.part_group = B.part_group
WHERE
b.[order_month] IS NULL AND
A.shipto_group IS NOT NULL
) AS C
INNER JOIN
( SELECT DISTINCT CAST(Left([order_month],2) AS INT) AS [order_month_idx], [order_month]
FROM #FY2019
) AS D ON C.order_month_idx = D.Order_month_idx
) AS MAPPED
INNER JOIN
( SELECT
MAX([bill_cust_descr]) AS bill_cust_descr
,MAX([billto_group]) AS billto_group
,MAX([ship_cust_descr]) AS ship_cust_descr
,shipto_group
,MAX([dsm]) AS dsm
,MAX([quota_rep_descr]) AS quota_rep_descr
,MAX([director]) AS [director]
,MAX([segm]) AS [segm]
,MAX([substance]) AS [substance]
,MAX([chan]) AS [chan]
,MAX([chansub]) AS [chansub]
,MAX([chan_retail]) AS [chan_retail]
,MAX([part]) AS [part]
,[part_descr]
,[part_group]
,MAX([branding]) AS [branding]
,MAX([majg_descr]) AS [majg_descr]
,MAX([ming_descr]) AS [ming_descr]
,MAX([majs_descr]) AS [majs_descr]
,MAX([mins_descr]) AS [mins_descr]
,MAX([order_date]) AS [order_date]
,MAX([order_season]) AS [order_season]
,MAX([order_month]) AS [order_month]
,MAX([ship_date]) AS [ship_date]
,MAX([ship_season]) AS [ship_season]
,MAX([ship_month]) AS [ship_month]
,MAX([request_date]) AS [request_date]
,MAX([request_season]) AS [request_season]
,MAX([request_month]) AS [request_month]
,MAX([promo]) AS [promo]
,MAX([fs_line]) as [fs_line]
,MAX([r_currency]) as [r_currency]
,MAX([c_currency]) as [c_currency]
,SUM([value_loc]) AS [value_loc]
,SUM([value_usd]) AS [value_usd]
,SUM([cost_loc]) AS [cost_loc]
,SUM([cost_usd]) AS [cost_usd]
,SUM([units]) AS [units]
,SUM([pounds]) AS [pounds]
,MAX([version]) AS [version]
,MAX([iter]) AS [iter]
,MAX([logid]) AS [logid]
,MAX([tag]) AS [tag]
,MAX([comment]) AS [comment]
,MAX([Promise Month]) AS [promise_month]
,MAX([Data Source]) AS [Data Source]
,MAX([Order Status])AS [Order Status]
,MAX([Promise Season]) AS [promise_season]
FROM #BASE_DATA
GROUP BY shipto_group, /*[part],*/ [part_descr], [part_group]
) AS DETAIL
ON MAPPED.shipto_group = DETAIL.shipto_group AND MAPPED.part_group = DETAIL.part_group
-- ORDER BY shipto_group, part_group, order_season, order_month
--
UNION ALL
--
-- 2019 ORDERS & 2022 ORDERS for Reference --
SELECT
CASE
WHEN [Ship Season] IS NULL THEN CAST([Promise Season] % 100 AS varchar) + LEFT([Promise Month], 2)
ELSE CAST([Ship Season] % 100 AS varchar) + LEFT([Ship Month], 2)
END AS [fspr]
,NULL as [plnt]
,[Promo Code] AS [promo]
,NULL as [terms]
,[Bill-To] AS bill_cust_descr
,[Ship-To] AS ship_cust_descr
,CASE WHEN [Quota Rep] LIKE '[0-9][0-9][0-9][0-9][0-9] -%' THEN LEFT([Quota Rep],5) ELSE NULL END AS [dsm]
,CASE WHEN [Quota Rep] LIKE '[0-9][0-9][0-9][0-9][0-9] -%' THEN SUBSTRING(RTRIM([Quota Rep]), 9, LEN([Quota Rep])-8) ELSE LTRIM(RTRIM([Quota Rep])) END AS [quota_rep_descr]
,[Director] AS [director]
,[Bill-To Group] AS billto_group
,[Ship-To Group] AS shipto_group
,[Channel] AS [chan]
,[Channel Sub] AS [chansub]
,[Channel - Retail] AS [chan_retail]
,[Part Code] AS [part]
,[Part Group Descr] AS [part_descr]
,[Part Group] AS [part_group]
,[Branding Flag] AS [branding]
,LEFT([Major Group],5) + ' ' + [Major Group] AS [majg_descr]
,LEFT([Minor Group],5) + ' ' + [Minor Group] AS [ming_descr]
,LEFT([Major Sales Group],5) + ' ' + [Major Sales Group] AS [majs_descr]
,LEFT([Minor Sales Group],5) + ' ' + [Minor Sales Group] AS [mins_descr]
,[Segment] AS [segm]
,CASE WHEN [Major Group] LIKE '610%' THEN 'Fiber' ELSE 'Plastic' END [substance]
,[Financial Statement Line] as [fs_line]
,[Inventory Currency] as [r_currency]
,[Value USD]/nullif([Value Local],0) as [r_rate]
,[Order Currency] as [c_currency]
,[Std Cost USD - Current]/nullif([Std Cost Local - Current],0) as [c_rate]
,[Units] AS [units]
,[value local] AS [value_loc]
,[value usd] AS [value_usd]
,[Standard Cost Local - Historic] AS [cost_loc]
,[Std Cost USD - Historic] AS [cost_usd]
,'CLOSED' as [calc_status]
,'SHIPMENT' as [flag]
,[Order Date] AS [order_date]
,[Order Month] AS [order_month]
,[Order Season] AS [order_season]
,[Request Date] AS [request_date]
,[Request Month] AS [request_month]
,[Request Season] AS [request_season]
,[Ship Date] AS [ship_date]
,[Ship Month] AS [ship_month]
,[Ship Season] AS [ship_season]
,'b24' AS [version]
,'actuals' AS [iter]
,1 AS [logid]
,'baseline' AS [tag]
,'don''t undo' AS [comment]
,'build_pool' as [module]
,[Pounds] AS [pounds]
FROM [FAnalysis].[RLARP].[osm_stack_pretty_wSTATUS]
WHERE ([Data Source] = 'Actual' AND [Order Season] IN(2019,2022)) AND [Ship-To Group] IS NOT NULL AND [part group] <> '' --jps04/25/2023 Included 2022 Data for refernece per users request
--
UNION ALL
--
-- OPEN ORDERS GOING INTO THE BEGINNING OF 2024 SEASON --
-- THESE WERE BACKED OUT OF THE 2024 BASELINE --
SELECT
CASE
WHEN [Ship Season] IS NULL THEN CAST([Promise Season] % 100 AS varchar) + LEFT([Promise Month], 2)
ELSE CAST([Ship Season] % 100 AS varchar) + LEFT([Ship Month], 2)
END AS [fspr]
,NULL as [plnt]
,[Promo Code] AS [promo]
,NULL as [terms]
,[Bill-To] AS bill_cust_descr
,[Ship-To] AS ship_cust_descr
,CASE WHEN [Quota Rep] LIKE '[0-9][0-9][0-9][0-9][0-9] -%' THEN LEFT([Quota Rep],5) ELSE NULL END AS [dsm]
,CASE WHEN [Quota Rep] LIKE '[0-9][0-9][0-9][0-9][0-9] -%' THEN SUBSTRING(RTRIM([Quota Rep]), 9, LEN([Quota Rep])-8) ELSE LTRIM(RTRIM([Quota Rep])) END AS [quota_rep_descr]
,[Director] AS [director]
,[Bill-To Group] AS billto_group
,[Ship-To Group] AS shipto_group
,[Channel] AS [chan]
,[Channel Sub] AS [chansub]
,[Channel - Retail] AS [chan_retail]
,[Part Code] AS [part]
,[Part Group Descr] AS [part_descr]
,[Part Group] AS [part_group]
,[Branding Flag] AS [branding]
,LEFT([Major Group],5) + ' ' + [Major Group] AS [majg_descr]
,LEFT([Minor Group],5) + ' ' + [Minor Group] AS [ming_descr]
,LEFT([Major Sales Group],5) + ' ' + [Major Sales Group] AS [majs_descr]
,LEFT([Minor Sales Group],5) + ' ' + [Minor Sales Group] AS [mins_descr]
,[Segment] AS [segm]
,CASE WHEN [Major Group] LIKE '610%' THEN 'Fiber' ELSE 'Plastic' END [substance]
,[Financial Statement Line] as [fs_line]
,[Inventory Currency] as [r_currency]
,[Value USD]/nullif([Value Local],0) as [r_rate]
,[Order Currency] as [c_currency]
,[Std Cost USD - Current]/nullif([Std Cost Local - Current],0) as [c_rate]
,[Units] AS [units]
,[value local] AS [value_loc]
,[value usd] AS [value_usd]
,[Standard Cost Local - Historic] AS [cost_loc]
,[Std Cost USD - Historic] AS [cost_usd]
,'BACKORDER' as [calc_status]
,'REMAINDER' as [flag]
,[Order Date] AS [order_date]
,[Order Month] AS [order_month]
,'2024' AS [order_season] --jps04/25/2023 Changed order season to 2024 so these show up under 2024 in pivot table
,[Request Date] AS [request_date]
,[Request Month] AS [request_month]
,[Request Season] AS [request_season]
,[Ship Date] AS [ship_date]
,[Ship Month] AS [ship_month]
,[Ship Season] AS [ship_season]
,'b24' AS [version]
,'actuals' AS [iter]
,1 AS [logid]
,'open-orders' AS [tag] --jps04/25/2023 Change to 'Open-orders' to stinguish these records from the 2024 baseline records
,'don''t undo' AS [comment]
,'build_pool' as [module]
,[Pounds] AS [pounds]
FROM [FAnalysis].[RLARP].[osm_stack_pretty_wSTATUS]
WHERE [Data Source] = 'Actual' AND [Order Status] = 'Open - Current' AND [Promise Season] > 2023
--- CLEANUP --
DROP TABLE #FY2019
DROP TABLE #FY2023
DROP TABLE #BASE_DATA
/*
/* OUTPUTS FOR DEBUG AND VALIDATION*/
-- Select * FROM #BASE_DATA
-- ORDER BY shipto_group, part_group
--
-- Select * FROM #FY2019
-- ORDER BY shipto_group, part_group
--
-- SELECT
-- [shipto_group]
-- ,[part_group]
-- ,[order_month]
-- ,SUM([value_loc]) AS [value_loc]
-- ,SUM([value_usd]) AS [value_usd]
-- ,SUM([cost_loc]) AS [cost_loc]
-- ,SUM([cost_usd]) AS [cost_usd]
-- ,SUM([units]) AS [units]
-- ,SUM([pounds]) AS [pounds]
-- ,SUM([Distribution_Factor]) AS [Distribution_Factor]
-- FROM(
-- Select /* 2019 Orders*/
-- CASE WHEN SUM([units]) OVER (Partition by [Ship-To Group], [Part Group]) <> 0 THEN [units] / SUM([units]) OVER (Partition by [Ship-To Group], [Part Group]) ELSE NULL END AS [Distribution_Factor]
-- ,[Bill-To] AS bill_cust_descr
-- ,[Bill-To Group] AS billto_group
-- ,[Ship-To] AS ship_cust_descr
-- ,[Ship-To Group] AS shipto_group
-- ,CASE WHEN Right(Left([Quota Rep], 7), 1) = '-' THEN RIGHT(LTRIM(RTRIM([Quota Rep])), Len([Quota Rep]) - 7) ELSE LTRIM(RTRIM([Quota Rep])) END AS [quota_rep_descr]
-- ,[Director] AS [director]
-- ,[Segment] AS [segm]
-- ,CASE WHEN [Major Group] LIKE '610%' THEN 'Fiber' ELSE 'Plastic' END [substance]
-- ,[Channel] AS [chan]
-- ,[Channel Sub] AS [chansub]
-- ,[Part Group Descr] AS [part_descr]
-- ,[Part Group] AS [part_group]
-- ,[Branding Flag] AS [branding]
-- ,LEFT([Major Group],5) + ' ' + [Major Group] AS [majg_descr]
-- ,LEFT([Minor Group],5) + ' ' + [Minor Group] AS [ming_descr]
-- ,LEFT([Major Sales Group],5) + ' ' + [Major Sales Group] AS [majs_descr]
-- ,LEFT([Minor Sales Group],5) + ' ' + [Minor Sales Group] AS [mins_descr]
-- ,[Order Season] AS [order_season]
-- ,[Order Month] AS [order_month]
-- ,[Ship Season] AS [ship_season]
-- ,[Ship Month] AS [ship_month]
-- ,[Request Season] AS [request_season]
-- ,[Request Month] AS [request_month]
-- ,[Promo Code] AS [promo]
-- ,[value local] AS [value_loc]
-- ,[value usd] AS [value_usd]
-- ,[Standard Cost Local - Historic] AS [cost_loc]
-- ,[Std Cost USD - Historic] AS [cost_usd]
-- ,[Units] AS [units]
-- ,[Pounds] AS [pounds]
-- ,'b24' AS [version]
-- ,'actuals' AS [iter]
-- ,1 AS [logid]
-- ,'baseline' AS [tag]
-- ,'don''t undo' AS [comment]
-- FROM [FAnalysis].[RLARP].[osm_stack_pretty_wSTATUS]
-- WHERE [Data Source] = 'Actual' AND [Order Season] = 2019
-- ) AS B
-- GROUP BY B.shipto_group, B.part_group, B.order_month
-- ORDER BY shipto_group, part_group, order_month
--
*/