Commit 901b356c authored by prumde's avatar prumde

Updated

git-svn-id: http://15.206.35.175/svn/proteus/business-java/trunk@217071 ce508802-f39f-4f6c-b175-0d175dae99d5
parent 14f4eb56
-- Sells Planning Review Dashboard of ABM and RSM
----------ABM INSERT DM-------------------------------------------------------------------------------
----------DELETE ABM DM-------------------------------------------------------------------------------
delete from DATA_MODEL where DATA_MODEL = 'SELL_PLAN_REVIEW_ABM_DM';
delete from DATA_MODEL_INPUT where DATA_MODEL = 'SELL_PLAN_REVIEW_ABM_DM';
delete from DATA_MODEL_USE where DATA_MODEL = 'SELL_PLAN_REVIEW_ABM_DM';
Insert into DATA_MODEL (DATA_MODEL,DESCR,DATA_SOURCE,SOURCE_DET,SOURCE_INPUT,FORMAT,CHG_DATE,CHG_USER,CHG_TERM,VALID_DAYS,SCOPE_NAME,SYNC_DATA_MODEL,COLUMN_ORDER)
values ('SELL_PLAN_REVIEW_ABM_DM','Sell Planning Review ABM Dashboard','S',
'
SELECT SELL_PLAN_DET.EMP_CODE,
SELL_PLAN_DET.EMP_NAME,
SELL_PLAN_DET.DESIGNATION,
SELL_PLAN_DET.POSITION_DESCR,
SELL_PLAN_DET.PRODUCT_CODE,
SELL_PLAN_DET.PRODUCT_DESCR,
SELL_PLAN_DET.SORT_ORDER,
NVL(ACHIVE_IN_OUT.SELL_IN,0 ) AS SELL_IN,
NVL(ACHIVE_IN_OUT.SELL_OUT,0 ) AS SELL_OUT
FROM
(
SELECT USER_HIERARCHY.EMP_CODE,
EMP.EMP_FNAME || '' '' || EMP.EMP_LNAME AS EMP_NAME,
EMP.DESIGNATION,
(CASE WHEN USER_HIERARCHY.LEVEL_NO = 7 THEN ''ABM'' ELSE ''ESI'' END ) AS POSITION_DESCR,
P.PRODUCT_CODE,
P.DESCR AS PRODUCT_DESCR,
P.SORT_ORDER AS SORT_ORDER
FROM PRODUCT P,
(
SELECT EMP_CODE,
LEVEL_NO
FROM ORG_STRUCTURE
WHERE EMP_CODE <> ?
START WITH EMP_CODE = ?
CONNECT BY PRIOR POS_CODE = POS_CODE__REPTO
) USER_HIERARCHY
INNER JOIN EMPLOYEE EMP ON USER_HIERARCHY.EMP_CODE = EMP.EMP_CODE AND EMP.STATUS = ''Y''
) SELL_PLAN_DET
LEFT OUTER JOIN TABLE(SELL_IN_OUT_PKG.GET_SELL_IN_OUT(SELL_PLAN_DET.EMP_CODE)) ACHIVE_IN_OUT ON SELL_PLAN_DET.PRODUCT_CODE = ACHIVE_IN_OUT.PRODUCT_CODE
WHERE SELL_PLAN_DET.PRODUCT_CODE NOT IN (''GRP03'')
ORDER BY
SELL_PLAN_DET.POSITION_DESCR,
SELL_PLAN_DET.EMP_CODE,
SELL_PLAN_DET.SORT_ORDER
',
':empCode,:empCode','json',
SYSDATE,'ADMIN','SYSTEM',null,
'FromDate'||'&'||'ToDate'||'&'||'empCode',
null,null);
Insert into DATA_MODEL_INPUT (DATA_MODEL,OBJ_NAME,MODEL_ARGS_BL,SCOPE_NAME,LINE_NO) values ('SELL_PLAN_REVIEW_ABM_DM','sell_plan_review_abm',null,null,'1 ');
----------DELETE RSM DM-------------------------------------------------------------------------------
delete from DATA_MODEL where DATA_MODEL = 'SELL_PLAN_REVIEW_RSM_DM';
delete from DATA_MODEL_INPUT where DATA_MODEL = 'SELL_PLAN_REVIEW_RSM_DM';
delete from DATA_MODEL_USE where DATA_MODEL = 'SELL_PLAN_REVIEW_RSM_DM';
Insert into DATA_MODEL_USE (DATA_MODEL,OBJ_NAME,FORM_NAME,FIELD_NAME,IS_CRITICAL,POPHELP) values ('SELL_PLAN_REVIEW_ABM_DM','sell_plan_review_abm',null,null,'Y',null);
----------NSM, GSM, RSM and ABM ALL ROLES DM INSERT START---------------------------------------------
delete from DATA_MODEL where DATA_MODEL = 'SELL_PLAN_REVIEW_ALL_DM';
delete from DATA_MODEL_INPUT where DATA_MODEL = 'SELL_PLAN_REVIEW_ALL_DM';
delete from DATA_MODEL_USE where DATA_MODEL = 'SELL_PLAN_REVIEW_ALL_DM';
----------ABM INSERT DM END-------------------------------------------------------------------------------
-- Sells Planning Review Dashboard of ABM and RSM
----------DELETE ABM DM-------------------------------------------------------------------------------
delete from DATA_MODEL where DATA_MODEL = 'SELL_PLAN_REVIEW_ABM_DM';
delete from DATA_MODEL_INPUT where DATA_MODEL = 'SELL_PLAN_REVIEW_ABM_DM';
delete from DATA_MODEL_USE where DATA_MODEL = 'SELL_PLAN_REVIEW_ABM_DM';
----------RSM INSERT DM-------------------------------------------------------------------------------
----------DELETE RSM DM-------------------------------------------------------------------------------
delete from DATA_MODEL where DATA_MODEL = 'SELL_PLAN_REVIEW_RSM_DM';
delete from DATA_MODEL_INPUT where DATA_MODEL = 'SELL_PLAN_REVIEW_RSM_DM';
delete from DATA_MODEL_USE where DATA_MODEL = 'SELL_PLAN_REVIEW_RSM_DM';
Insert into DATA_MODEL (DATA_MODEL,DESCR,DATA_SOURCE,SOURCE_DET,SOURCE_INPUT,FORMAT,CHG_DATE,CHG_USER,CHG_TERM,VALID_DAYS,SCOPE_NAME,SYNC_DATA_MODEL,COLUMN_ORDER) values ('SELL_PLAN_REVIEW_RSM_DM','Coaching RSM Dashboard','S',
----------DELETE GSM DM-------------------------------------------------------------------------------
delete from DATA_MODEL where DATA_MODEL = 'SELL_PLAN_REVIEW_GSM_DM';
delete from DATA_MODEL_INPUT where DATA_MODEL = 'SELL_PLAN_REVIEW_GSM_DM';
delete from DATA_MODEL_USE where DATA_MODEL = 'SELL_PLAN_REVIEW_GSM_DM';
----------DELETE NSM DM-------------------------------------------------------------------------------
delete from DATA_MODEL where DATA_MODEL = 'SELL_PLAN_REVIEW_NSM_DM';
delete from DATA_MODEL_INPUT where DATA_MODEL = 'SELL_PLAN_REVIEW_NSM_DM';
delete from DATA_MODEL_USE where DATA_MODEL = 'SELL_PLAN_REVIEW_NSM_DM';
Insert into DATA_MODEL (DATA_MODEL,DESCR,DATA_SOURCE,SOURCE_DET,SOURCE_INPUT,FORMAT,CHG_DATE,CHG_USER,CHG_TERM,VALID_DAYS,SCOPE_NAME,SYNC_DATA_MODEL,COLUMN_ORDER) values ('SELL_PLAN_REVIEW_ALL_DM','Sells Plan Review Dashboard NSM, GSM, RSM and ABM ALL ROLES DM','S',
'
SELECT
SELL_PLAN_DET.EMP_CODE,
SELL_PLAN_DET.EMP_NAME,
(CASE WHEN SELL_PLAN_DET.STATUS LIKE ''N'' THEN ''Vacant'' ELSE SELL_PLAN_DET.EMP_NAME END) AS EMP_NAME,
(CASE WHEN SELL_PLAN_DET.STATUS LIKE ''N'' THEN ''location_g.svg'' ELSE '''' END ) AS VACANT_IMAGE,
SELL_PLAN_DET.DESIGNATION,
SELL_PLAN_DET.DESIGN_CODE,
SELL_PLAN_DET.STATION_DESCR,
SELL_PLAN_DET.POSITION_DESCR,
SELL_PLAN_DET.REPORT_TO,
SELL_PLAN_DET.PRODUCT_CODE,
......@@ -81,22 +65,33 @@ FROM
SELECT USER_HIERARCHY.EMP_CODE,
EMP.EMP_FNAME || '' '' || EMP.EMP_LNAME AS EMP_NAME,
EMP.DESIGNATION,
(CASE WHEN USER_HIERARCHY.LEVEL_NO = 7 THEN ''ABM'' ELSE ''ESI'' END ) AS POSITION_DESCR,
EMP.DESIGN_CODE,
EMP.STATUS,
(SELECT DESCR FROM STATION WHERE STAN_CODE = USER_HIERARCHY.STAN_CODE__HQ ) AS STATION_DESCR,
(
CASE
WHEN USER_HIERARCHY.LEVEL_NO = 5 THEN ''GSM''
WHEN USER_HIERARCHY.LEVEL_NO = 6 THEN ''RSM''
WHEN USER_HIERARCHY.LEVEL_NO = 7 THEN ''ABM''
WHEN USER_HIERARCHY.LEVEL_NO = 8 THEN ''ESI''
END
) AS POSITION_DESCR,
USER_HIERARCHY.REPORT_TO,
P.PRODUCT_CODE,
P.DESCR AS PRODUCT_DESCR,
P.SORT_ORDER AS SORT_ORDER
FROM PRODUCT P,
(
SELECT EMP_CODE,
SELECT O1.EMP_CODE,
(SELECT EMP_CODE FROM ORG_STRUCTURE WHERE POS_CODE = O1.POS_CODE__REPTO) AS REPORT_TO,
LEVEL_NO
O1.LEVEL_NO,
O1.STAN_CODE__HQ
FROM ORG_STRUCTURE O1
WHERE EMP_CODE <> ?
START WITH EMP_CODE = ?
CONNECT BY PRIOR POS_CODE = POS_CODE__REPTO
WHERE O1.EMP_CODE <> ?
START WITH O1.EMP_CODE = ?
CONNECT BY PRIOR O1.POS_CODE = O1.POS_CODE__REPTO
) USER_HIERARCHY
INNER JOIN EMPLOYEE EMP ON USER_HIERARCHY.EMP_CODE = EMP.EMP_CODE AND EMP.STATUS = ''Y''
INNER JOIN EMPLOYEE EMP ON USER_HIERARCHY.EMP_CODE = EMP.EMP_CODE AND EMP.DESIGN_CODE <> ''ERE''
) SELL_PLAN_DET
LEFT OUTER JOIN TABLE(SELL_IN_OUT_PKG.GET_SELL_IN_OUT(SELL_PLAN_DET.EMP_CODE)) ACHIVE_IN_OUT ON SELL_PLAN_DET.PRODUCT_CODE = ACHIVE_IN_OUT.PRODUCT_CODE
WHERE SELL_PLAN_DET.PRODUCT_CODE NOT IN (''GRP03'')
......@@ -110,12 +105,11 @@ ORDER BY
'FromDate'||'&'||'ToDate'||'&'||'empCode',
null,null);
Insert into DATA_MODEL_INPUT (DATA_MODEL,OBJ_NAME,MODEL_ARGS_BL,SCOPE_NAME,LINE_NO) values ('SELL_PLAN_REVIEW_RSM_DM','sell_plan_review_rsm',null,null,'1 ');
Insert into DATA_MODEL_USE (DATA_MODEL,OBJ_NAME,FORM_NAME,FIELD_NAME,IS_CRITICAL,POPHELP) values ('SELL_PLAN_REVIEW_RSM_DM','sell_plan_review_rsm',null,null,'Y',null);
Insert into DATA_MODEL_INPUT (DATA_MODEL,OBJ_NAME,MODEL_ARGS_BL,SCOPE_NAME,LINE_NO) values ('SELL_PLAN_REVIEW_ALL_DM','sp_review_gsm_nsm',null,null,'1 ');
----------RSM INSERT DM END-------------------------------------------------------------------------------
Insert into DATA_MODEL_USE (DATA_MODEL,OBJ_NAME,FORM_NAME,FIELD_NAME,IS_CRITICAL,POPHELP) values ('SELL_PLAN_REVIEW_ALL_DM','sp_review_gsm_nsm',null,null,'Y',null);
----------NSM, GSM, RSM and ABM ALL ROLES DM END-------------------------------------------------------------------------------
......@@ -135,14 +129,15 @@ WITH TEAM as (SELECT EMP_CODE,
START WITH EMP_CODE = ?
CONNECT BY PRIOR POS_CODE = POS_CODE__REPTO
)
SELECT T.EMP_CODE, T.EMP_NAME, T.REPORT_TO, SP.TRAN_ID, SPD.LINE_NO, SP.TRAN_DATE,
SELECT T.EMP_CODE, T.EMP_NAME, T.REPORT_TO,
SP.TRAN_ID, SPD.LINE_NO, SP.TRAN_DATE,
SPD.SC_CODE, (SELECT FIRST_NAME || '' '' || LAST_NAME FROM STRG_CUSTOMER WHERE SC_CODE = SPD.SC_CODE ) as Dealer_Name,
SPD.ITEM_CODE, I.DESCR as Product_Name, I.PRODUCT_CODE, P.MKT_ARR,
SPD.SELL_IN_QTY, SPD.SELL_IN_VALUE, SPD.SELL_OUT_QTY, SPD.SELL_OUT_VALUE,
CASE WHEN P.MKT_ARR = ''Y'' THEN SPD.SELL_IN_VALUE ELSE SPD.SELL_IN_QTY END AS SELL_IN,
CASE WHEN P.MKT_ARR = ''Y'' THEN SPD.SELL_OUT_VALUE ELSE SPD.SELL_OUT_QTY END AS SELL_OUT,
SPD.ITEM_CODE, I.DESCR as Product_Name,
I.PRODUCT_CODE, P.MKT_ARR,
CASE WHEN P.MKT_ARR = ''Y'' THEN SPD.SELL_IN_QTY ELSE SPD.SELL_IN_QTY END AS SELL_IN,
CASE WHEN P.MKT_ARR = ''Y'' THEN SPD.SELL_OUT_QTY ELSE SPD.SELL_OUT_QTY END AS SELL_OUT,
FN_GET_USER_TASK_DESCR( ?, T.EMP_CODE, SP.TRAN_ID || ''~'' || SPD.LINE_NO, ''SELL-P'') as Action,
NVL(FN_GET_RUNRATE(T.EMP_CODE, SPD.ITEM_CODE, SPD.SC_CODE, P.MKT_ARR, ''2''), 0) as RunRate
NVL(FN_GET_RUNRATE(T.EMP_CODE, SPD.ITEM_CODE, SPD.SC_CODE, ''N'', ''2''), 0) as RunRate
FROM TEAM T
LEFT OUTER JOIN SELLS_PLANNING SP ON T.EMP_CODE = SP.SALES_PERS
LEFT OUTER JOIN SELLS_PLANNING_DET SPD ON SP.TRAN_ID = SPD.TRAN_ID
......@@ -201,8 +196,118 @@ END;
---------------FN_GET_USER_TASK_DESCR Ends--------------------
---------------FN_GET_RUNRATE Starts--------------------
create or replace FUNCTION FN_GET_RUNRATE
(
AS_LOGIN_CODE IN CHAR,
AS_ITEM_CODE IN CHAR,
AS_SC_CODE IN CHAR,
AS_MKT_ARR IN CHAR,
AS_OPTION IN CHAR
)
RETURN NUMBER IS RUNRATE NUMBER(14,3);
AS_TRAN_ID CHAR(10);
SELL_OUT_QTY NUMBER(14, 3);
PLAN_SELL_OUT_QTY NUMBER(14, 3);
NO_OF_WEEK NUMBER(1);
NO_OF_WEEKS_IN_MTH NUMBER(1);
DIFF_IN_WEEK NUMBER(1);
WEEK_PLAN NUMBER(14, 3);
BEGIN
IF AS_MKT_ARR = 'Y' THEN
SELECT SPD.SELL_OUT_VALUE INTO PLAN_SELL_OUT_QTY
FROM SELLS_PLANNING SP, SELLS_PLANNING_DET SPD
WHERE SP.TRAN_ID = SPD.TRAN_ID
AND SP.SALES_PERS = AS_LOGIN_CODE
AND SPD.SC_CODE = AS_SC_CODE
AND SP.PRD_CODE = (SELECT CODE FROM PERIOD WHERE SYSDATE BETWEEN FR_DATE AND TO_DATE)
AND SPD.ITEM_CODE = AS_ITEM_CODE
AND SP.STATUS = 'S';
SELECT IN_OUT_DET.SELL_OUT_VALUE INTO SELL_OUT_QTY
FROM STK_SELL_IN_OUT IN_OUT, STK_SELL_IN_OUT_DET IN_OUT_DET
WHERE IN_OUT.TRAN_ID = IN_OUT_DET.TRAN_ID
AND IN_OUT.SALES_PERS = AS_LOGIN_CODE
AND IN_OUT_DET.ITEM_CODE = AS_ITEM_CODE
AND IN_OUT.PRD_CODE = (SELECT CODE FROM PERIOD WHERE SYSDATE BETWEEN FR_DATE AND TO_DATE)
AND IN_OUT.SC_CODE = AS_SC_CODE
AND IN_OUT.STATUS = 'A';
ELSE
SELECT SPD.SELL_OUT_QTY INTO PLAN_SELL_OUT_QTY
FROM SELLS_PLANNING SP, SELLS_PLANNING_DET SPD
WHERE SP.TRAN_ID = SPD.TRAN_ID
AND SP.SALES_PERS = AS_LOGIN_CODE
AND SPD.SC_CODE = AS_SC_CODE
AND SP.PRD_CODE = (SELECT CODE FROM PERIOD WHERE SYSDATE BETWEEN FR_DATE AND TO_DATE)
AND SPD.ITEM_CODE = AS_ITEM_CODE
AND SP.STATUS = 'S';
SELECT IN_OUT_DET.SELL_OUT_QTY INTO SELL_OUT_QTY
FROM STK_SELL_IN_OUT IN_OUT, STK_SELL_IN_OUT_DET IN_OUT_DET
WHERE IN_OUT.TRAN_ID = IN_OUT_DET.TRAN_ID
AND IN_OUT.SALES_PERS = AS_LOGIN_CODE
AND IN_OUT_DET.ITEM_CODE = AS_ITEM_CODE
AND IN_OUT.PRD_CODE = (SELECT CODE FROM PERIOD WHERE SYSDATE BETWEEN FR_DATE AND TO_DATE)
AND IN_OUT.SC_CODE = AS_SC_CODE
AND IN_OUT.STATUS = 'A';
END IF;
IF AS_OPTION = '1' THEN
SELECT TO_CHAR(SYSDATE,'W') INTO NO_OF_WEEK FROM DUAL;
SELECT ROUND(1+(D2-D1)/7) AS WEEK INTO NO_OF_WEEKS_IN_MTH
FROM (SELECT TO_DATE (ADD_MONTHS(TRUNC(sysdate,'mm'),0)) D1, TO_DATE (sysdate) D2 FROM dual) date_range;
DIFF_IN_WEEK := NO_OF_WEEKS_IN_MTH - NO_OF_WEEK;
IF DIFF_IN_WEEK = 0 then
DIFF_IN_WEEK := 1;
END IF;
RUNRATE := ( ( PLAN_SELL_OUT_QTY - SELL_OUT_QTY ) / DIFF_IN_WEEK);
ELSE
SELECT ROUND(1+(D2-D1)/7) AS WEEK INTO NO_OF_WEEKS_IN_MTH
FROM (SELECT TO_DATE (ADD_MONTHS(TRUNC(sysdate,'mm'),0)) D1, TO_DATE (sysdate) D2 FROM dual) date_range;
WEEK_PLAN := ( PLAN_SELL_OUT_QTY / NO_OF_WEEKS_IN_MTH);
RUNRATE := ( ( WEEK_PLAN - SELL_OUT_QTY) + (WEEK_PLAN * ( NO_OF_WEEKS_IN_MTH - 1 )));
END IF;
RETURN NVL(RUNRATE,0);
END;
/
---------------FN_GET_RUNRATE Ends--------------------
/****************************Package Start******************************************/
-- Package Object Types : SELL_IN_OUT_MST, SIO_TABLE
create or replace TYPE SELL_IN_OUT_MST
AS
OBJECT
(
PRODUCT_CODE CHAR(20),
SELL_IN VARCHAR2(20) ,
SELL_OUT VARCHAR2(120)
);
/
create or replace TYPE SIO_TABLE AS TABLE OF SELL_IN_OUT_MST;
/
-- Package Definition
CREATE OR REPLACE PACKAGE SELL_IN_OUT_PKG
......@@ -229,8 +334,8 @@ for x in(
P.PRODUCT_CODE,
SPD.ITEM_CODE,
SPD.SC_CODE,
CASE WHEN P.MKT_ARR = 'Y' THEN SPD.SELL_IN_VALUE ELSE SPD.SELL_IN_QTY END AS SELL_IN,
CASE WHEN P.MKT_ARR = 'Y' THEN SPD.SELL_OUT_VALUE ELSE SPD.SELL_OUT_QTY END AS SELL_OUT
CASE WHEN P.MKT_ARR = 'Y' THEN SPD.SELL_IN_QTY ELSE SPD.SELL_IN_QTY END AS SELL_IN,
CASE WHEN P.MKT_ARR = 'Y' THEN SPD.SELL_OUT_QTY ELSE SPD.SELL_OUT_QTY END AS SELL_OUT
FROM SELLS_PLANNING SP
LEFT OUTER JOIN SELLS_PLANNING_DET SPD ON SP.TRAN_ID = SPD.TRAN_ID
LEFT OUTER JOIN ITEM I ON SPD.ITEM_CODE = I.ITEM_CODE
......@@ -249,8 +354,8 @@ for x in(
P.PRODUCT_CODE,
SSIO.SC_CODE,
SSIOD.ITEM_CODE,
CASE WHEN P.MKT_ARR = 'Y' THEN SSIOD.SELL_IN_VALUE ELSE SSIOD.SELL_IN_QTY END AS SELL_IN,
CASE WHEN P.MKT_ARR = 'Y' THEN SSIOD.SELL_OUT_VALUE ELSE SSIOD.SELL_OUT_QTY END AS SELL_OUT
CASE WHEN P.MKT_ARR = 'Y' THEN SSIOD.SELL_IN_QTY ELSE SSIOD.SELL_IN_QTY END AS SELL_IN,
CASE WHEN P.MKT_ARR = 'Y' THEN SSIOD.SELL_OUT_QTY ELSE SSIOD.SELL_OUT_QTY END AS SELL_OUT
FROM STK_SELL_IN_OUT SSIO
LEFT OUTER JOIN STK_SELL_IN_OUT_DET SSIOD ON SSIO.TRAN_ID = SSIOD.TRAN_ID
LEFT OUTER JOIN ITEM I ON SSIOD.ITEM_CODE = I.ITEM_CODE
......@@ -293,21 +398,4 @@ END;
END SELL_IN_OUT_PKG;
/
-- Package Object Types : SELL_IN_OUT_MST, SIO_TABLE
create or replace TYPE SELL_IN_OUT_MST
AS
OBJECT
(
PRODUCT_CODE CHAR(20),
SELL_IN VARCHAR2(20) ,
SELL_OUT VARCHAR2(120)
);
/
create or replace TYPE SIO_TABLE AS TABLE OF SELL_IN_OUT_MST;
/
/****************************Package End******************************************/
\ No newline at end of file
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment