Commit 78fdbe82 authored by prumde's avatar prumde

Added for Sales Performance Dashboard

git-svn-id: http://15.206.35.175/svn/proteus/business-java/trunk@217941 ce508802-f39f-4f6c-b175-0d175dae99d5
parent 6bc48a9e
Insert into CHCSFA.DASHBOARD_COMP (USER_ID,PAGE_ID,COMP_ID,TITLE,URI,WIDTH,HEIGHT,ROW_NO,COLUMN_NO,COMP_TYPE,COMP_NAME,
ENTITY_TYPE,ENTITY_CODE,DBR_RESOURCE,DATA_MODEL)
values (<PROFILE_ID>,<PAGE_ID>,1,'Sales Performance',null,350,0,0,1,'ANG','ANG','F',<PROFILE_ID>,'chc_sales_performance',null);
Insert into CHCSFA.DASHBOARD_PAGES (USER_ID,PAGE_ID,TITLE,URI,IMAGE_URI,PAGE_TYPE,ENTITY_TYPE,ENTITY_CODE,CHG_USER,CHG_TERM,
CHG_DATE,COMP_TYPE,DATA_MODEL,DBR_RESOURCE,COMP_NAME)
values (<PROFILE_ID>,<PAGE_ID>,'Sales Performance',null,null,'T','F',<PROFILE_ID>,'SYSTEM','SYSTEM',sysdate,'ANG ',null,null,'ANG');
delete from GENCODES where MOD_NAME = 'W_CHC_SALES_PERF_DM';
Insert into GENCODES (FLD_NAME,MOD_NAME,FLD_VALUE,DESCR,SH_DESCR,CHG_DATE,CHG_USER,CHG_TERM,ACTIVE,UDF_STR1,UDF_STR2,UDF_STR3)
values ('SALES_FW','W_CHC_SALES_PERF_DM','200','Field Work Days','YTD',SYSDATE,'SYSADM','SYSADM','Y','blue','chc_kpi_fw.svg','4');
Insert into GENCODES (FLD_NAME,MOD_NAME,FLD_VALUE,DESCR,SH_DESCR,CHG_DATE,CHG_USER,CHG_TERM,ACTIVE,UDF_STR1,UDF_STR2,UDF_STR3)
values ('SALES_TC','W_CHC_SALES_PERF_DM','8500','Total Calls','YTD',SYSDATE,'SYSADM','SYSADM','Y','violet','chc_kpi_tc.svg','5');
Insert into GENCODES (FLD_NAME,MOD_NAME,FLD_VALUE,DESCR,SH_DESCR,CHG_DATE,CHG_USER,CHG_TERM,ACTIVE,UDF_STR1,UDF_STR2,UDF_STR3)
values ('SALES_PC','W_CHC_SALES_PERF_DM','3840','Productive Calls','YTD',SYSDATE,'SYSADM','SYSADM','Y','green','chc_kpi_pc.svg','15');
Insert into GENCODES (FLD_NAME,MOD_NAME,FLD_VALUE,DESCR,SH_DESCR,CHG_DATE,CHG_USER,CHG_TERM,ACTIVE,UDF_STR1,UDF_STR2,UDF_STR3)
values ('SALES_PMPM','W_CHC_SALES_PERF_DM','1','Per Person Per Month','YTD',SYSDATE,'SYSADM','SYSADM','Y','orange','chc_kpi_pmpm.svg','1');
Insert into GENCODES (FLD_NAME,MOD_NAME,FLD_VALUE,DESCR,SH_DESCR,CHG_DATE,CHG_USER,CHG_TERM,ACTIVE,UDF_STR1,UDF_STR2,UDF_STR3)
values ('SALES_ACHIVMNT','W_CHC_SALES_PERF_DM','100','Sales Achievement','YTD',SYSDATE,'SYSADM','SYSADM','Y','orange','chc_kpi_achieve.svg','25');
Insert into GENCODES (FLD_NAME,MOD_NAME,FLD_VALUE,DESCR,SH_DESCR,CHG_DATE,CHG_USER,CHG_TERM,ACTIVE,UDF_STR1,UDF_STR2,UDF_STR3)
values ('SALES_GROWTH','W_CHC_SALES_PERF_DM','100','Sales Growth','YTD',SYSDATE,'SYSADM','SYSADM','Y','blue','chc_kpi_growth.svg','50');
Delete from SYSVIS.DATA_MODEL where DATA_MODEL = 'CHC_SALES_PERF_DM';
Delete from SYSVIS.DATA_MODEL_INPUT where DATA_MODEL = 'CHC_SALES_PERF_DM';
Delete from SYSVIS.DATA_MODEL_USE where DATA_MODEL = 'CHC_SALES_PERF_DM';
Insert into SYSVIS.DATA_MODEL (DATA_MODEL,DESCR,DATA_SOURCE,SOURCE_INPUT,FORMAT,CHG_DATE,CHG_USER,CHG_TERM,VALID_DAYS,SCOPE_NAME,SOURCE_DET)
values ('CHC_SALES_PERF_DM','Sales Performance Dashboard','S',
':empCode,:PRD_CODE,:PRD_CODE','json',SYSDATE,'ADMIN','SYSTEM',null,
'empCode',
'
SELECT FLD_NAME, DATA_GRP, TARGET_VALUE, ACTUAL_VALUE, WEIGHTAGE_VALUE, DESCR, SH_DESCR, THEME_COLOR, ICON
FROM TABLE( ChcSalesPerfDm.getChcSalesPerfData( ?, (CASE WHEN NVL(?,''NA'') = ''NA'' THEN ? ELSE TO_CHAR(SYSDATE,''YYYYMM'') END) ) )
');
Insert into SYSVIS.DATA_MODEL_INPUT (DATA_MODEL,OBJ_NAME,MODEL_ARGS_BL,LINE_NO,SCOPE_NAME)
values ('CHC_SALES_PERF_DM','chc_sales_perf_dm',null,'1 ',null);
Insert into SYSVIS.DATA_MODEL_USE (DATA_MODEL,OBJ_NAME,FORM_NAME,FIELD_NAME,IS_CRITICAL,POPHELP)
values ('CHC_SALES_PERF_DM','chc_sales_perf_dm',null,null,'Y',null);
------------------------------------------------------------------------------------------------
--
------------------------------------------------------------------------------------------------
Delete from SYSVIS.DATA_MODEL where DATA_MODEL = 'CHC_SALES_PERF_SUMMARY_DM';
Delete from SYSVIS.DATA_MODEL_INPUT where DATA_MODEL = 'CHC_SALES_PERF_SUMMARY_DM';
Delete from SYSVIS.DATA_MODEL_USE where DATA_MODEL = 'CHC_SALES_PERF_SUMMARY_DM';
Insert into SYSVIS.DATA_MODEL (DATA_MODEL,DESCR,DATA_SOURCE,SOURCE_INPUT,FORMAT,CHG_DATE,CHG_USER,CHG_TERM,VALID_DAYS,SCOPE_NAME,SOURCE_DET)
values ('CHC_SALES_PERF_SUMMARY_DM','Sales Performance Dashboard Summary','S',
':empCode,:empCode,:empCode','json',SYSDATE,'ADMIN','SYSTEM',null,
'empCode',
'
SELECT EMP_CODE,
TRIM(EMP_FNAME) || '' '' || TRIM(EMP_MNAME) || '' '' || TRIM(EMP_LNAME) AS EMP_NAME,
DESIGNATION,
''Joined on '' || TO_CHAR(DATE_JOIN, ''dd-MON-yyyy'') AS EMP_DOJ,
FN_GET_CHC_SALES_PERF(?, ''OVERALL_PERCENT'') AS OVERALL_PERCENT,
FN_GET_CHC_SALES_PERF(?, ''PERCENTILE'') AS PERCENTILE
FROM EMPLOYEE WHERE EMP_CODE = ?
');
Insert into SYSVIS.DATA_MODEL_INPUT (DATA_MODEL,OBJ_NAME,MODEL_ARGS_BL,LINE_NO,SCOPE_NAME)
values ('CHC_SALES_PERF_SUMMARY_DM','chc_sales_perf_summ_dm',null,'1 ',null);
Insert into SYSVIS.DATA_MODEL_USE (DATA_MODEL,OBJ_NAME,FORM_NAME,FIELD_NAME,IS_CRITICAL,POPHELP)
values ('CHC_SALES_PERF_SUMMARY_DM','chc_sales_perf_summ_dm',null,null,'Y',null);
-- To get No. of Field Work Days
create or replace FUNCTION FN_GET_CHC_KPI_FW(AS_OPT CHAR, AS_SALES_PERS VARCHAR, AS_DATE DATE)
RETURN NUMBER
IS
FW_VAL NUMBER;
BEGIN
IF AS_OPT = 'DAY' THEN
SELECT COUNT(DISTINCT SM.STRG_CODE) INTO FW_VAL
FROM STRG_MEET SM, FIELDACTIVITY F
WHERE SM.SALES_PERS = AS_SALES_PERS
AND TO_DATE(SM.EVENT_DATE) = TO_DATE(AS_DATE)
AND SM.EVENT_TYPE = F.ACTIVITY_CODE
AND F.ACTIVITY_TYPE= 'FW';
END IF;
IF AS_OPT = 'MTD' THEN
SELECT COUNT(DISTINCT SM.STRG_CODE) INTO FW_VAL
FROM STRG_MEET SM, FIELDACTIVITY F
WHERE SM.SALES_PERS = AS_SALES_PERS
AND TO_CHAR(TO_DATE(SM.EVENT_DATE),'mm/yy') = TO_CHAR(TO_DATE(AS_DATE,'dd/mm/yy'),'mm/yy')
AND SM.EVENT_TYPE = F.ACTIVITY_CODE
AND F.ACTIVITY_TYPE = 'FW';
END IF;
IF AS_OPT = 'YTD' THEN
SELECT COUNT(DISTINCT SM.STRG_CODE) INTO FW_VAL
FROM STRG_MEET SM, FIELDACTIVITY F
WHERE SM.SALES_PERS = AS_SALES_PERS
AND EXTRACT (YEAR FROM SM.EVENT_DATE) = EXTRACT(YEAR FROM TO_DATE(SYSDATE))
AND SM.EVENT_TYPE = F.ACTIVITY_CODE
AND F.ACTIVITY_TYPE = 'FW';
END IF;
RETURN FW_VAL;
END;
/
-- To calculate Sales Growth w.r.t. to previous Day / Year / Last Month / Last Years this Month
create or replace FUNCTION FN_GET_CHC_KPI_GROWTH(AS_OPT CHAR, AS_SALESPERS VARCHAR, AS_DATE date)
RETURN NUMBER
IS
CURRENT_VAL NUMBER (14,3);
CURRENT_VAL_CNT NUMBER (14,3);
PREV_VAL NUMBER (14,3);
PREV_VAL_CNT NUMBER (14,3);
FINAL_VAL NUMBER (14,3);
BEGIN
FINAL_VAL := 0;
--Sales Growth will be calculated for current day w.r.t. Previous Day
IF AS_OPT = 'DAY' THEN
SELECT SUM(SALES_VAL), COUNT(SALES_VAL) INTO CURRENT_VAL, CURRENT_VAL_CNT
FROM DWH_INV_SRET_SUM
WHERE EMP_CODE = AS_SALESPERS
AND TO_CHAR(TRAN_DATE, 'DD-MM-YYYY') = TO_CHAR(TO_DATE(AS_DATE), 'DD-MM-YYYY') ;
SELECT SUM(SALES_VAL), COUNT(SALES_VAL) INTO PREV_VAL, PREV_VAL_CNT
FROM DWH_INV_SRET_SUM
WHERE EMP_CODE = AS_SALESPERS
AND TO_CHAR(TRAN_DATE, 'DD-MM-YYYY') = TO_CHAR(TO_DATE(AS_DATE) -1, 'DD-MM-YYYY') ;
END IF;
--Sales Growth will be calculated for this month w.r.t. Last Month
IF AS_OPT = 'MTD' THEN
SELECT SUM(SALES_VAL), COUNT(SALES_VAL) INTO CURRENT_VAL, CURRENT_VAL_CNT
FROM DWH_INV_SRET_SUM
WHERE EMP_CODE = AS_SALESPERS
AND TO_CHAR(TRAN_DATE, 'YYYYMM') = TO_CHAR(TO_DATE(AS_DATE), 'YYYYMM') ;
SELECT SUM(SALES_VAL), COUNT(SALES_VAL) INTO PREV_VAL, PREV_VAL_CNT
FROM DWH_INV_SRET_SUM
WHERE EMP_CODE = AS_SALESPERS
AND TO_CHAR(TRAN_DATE, 'YYYYMM') = TO_CHAR(ADD_MONTHS(TO_DATE(AS_DATE), -1), 'YYYYMM') ;
END IF;
--Sales Growth will be calculated for this month w.r.t. Last Years this Month
IF AS_OPT = 'YTD' THEN
SELECT SUM(SALES_VAL), COUNT(SALES_VAL) INTO CURRENT_VAL, CURRENT_VAL_CNT
FROM DWH_INV_SRET_SUM
WHERE EMP_CODE = AS_SALESPERS
AND TO_CHAR(TRAN_DATE, 'YYYYMM') = TO_CHAR(TO_DATE(AS_DATE), 'YYYYMM') ;
SELECT SUM(SALES_VAL), COUNT(SALES_VAL) INTO PREV_VAL, PREV_VAL_CNT
FROM DWH_INV_SRET_SUM
WHERE EMP_CODE = AS_SALESPERS
AND TO_CHAR(TRAN_DATE, 'YYYYMM') = TO_CHAR(ADD_MONTHS(TO_DATE(AS_DATE), -12), 'YYYYMM') ;
END IF;
--Sales Growth will be calculated for this year w.r.t. previous year
IF AS_OPT = 'YEAR' THEN
SELECT SUM(SALES_VAL), COUNT(SALES_VAL) INTO CURRENT_VAL, CURRENT_VAL_CNT
FROM DWH_INV_SRET_SUM
WHERE EMP_CODE = AS_SALESPERS
AND TO_CHAR(TRAN_DATE, 'YYYY') = TO_CHAR(TO_DATE(AS_DATE), 'YYYY') ;
SELECT SUM(SALES_VAL), COUNT(SALES_VAL) INTO PREV_VAL, PREV_VAL_CNT
FROM DWH_INV_SRET_SUM
WHERE EMP_CODE = AS_SALESPERS
AND TO_CHAR(TRAN_DATE, 'YYYY') = TO_CHAR(ADD_MONTHS(TO_DATE(AS_DATE), -12), 'YYYY') ;
END IF;
IF CURRENT_VAL_CNT = 0 THEN
CURRENT_VAL := 0;
END IF;
IF PREV_VAL_CNT = 0 THEN
PREV_VAL := 0;
END IF;
IF CURRENT_VAL > 0 AND PREV_VAL > 0 THEN
FINAL_VAL := ( ( CURRENT_VAL - PREV_VAL ) / CURRENT_VAL ) * 100;
END IF;
RETURN FINAL_VAL;
END;
/
-- To calculate Sales Target
create or replace FUNCTION FN_GET_CHC_KPI_SALES_ACHIVMNT (AS_OPT CHAR, AS_SALESPERS VARCHAR)
RETURN NUMBER
IS
FINAL_VAL NUMBER(14,3);
TARGET_VAL NUMBER(14,3);
TARGET_VAL_CNT NUMBER(14,3);
SALES_VAL NUMBER(14,3);
NO_OF_SE NUMBER(14,3);
AS_TERR_CODE CHAR(10);
AS_FR_DATE DATE;
BEGIN
FINAL_VAL := 0;
--To get Territory Code of Provided Sales Person
SELECT POOL_CODE INTO AS_TERR_CODE
FROM ORG_STRUCTURE
WHERE EMP_CODE = AS_SALESPERS
AND VERSION_ID = (SELECT MAX(Q.VERSION_ID) FROM VERSION Q WHERE TRUNC(SYSDATE) BETWEEN Q.EFF_FROM AND Q.VALID_UPTO);
--To get Month to Date Sales Target Achivement
IF AS_OPT = 'MTD' THEN
SELECT FR_DATE INTO AS_FR_DATE
FROM PERIOD
WHERE TO_DATE(SYSDATE) BETWEEN FR_DATE AND TO_DATE;
END IF;
--To get Year to Date Sales Target Achivement
IF AS_OPT = 'YTD' THEN
SELECT FR_DATE INTO AS_FR_DATE
FROM ACCTPRD
WHERE TO_DATE(SYSDATE) BETWEEN FR_DATE AND TO_DATE;
END IF;
-- Get Sales Value
SELECT MAX(NO_OF_SE), SUM(SALES_VAL) INTO NO_OF_SE, SALES_VAL
FROM DWH_INV_SRET_SUM
WHERE TRAN_DATE BETWEEN AS_FR_DATE AND SYSDATE
AND TERRITORY_CODE = AS_TERR_CODE
AND EMP_CODE = AS_SALESPERS;
-- Get Target Value
SELECT SUM(SALES_TARGET_VAL), COUNT(SALES_TARGET_VAL) INTO TARGET_VAL, TARGET_VAL_CNT
FROM DWH_SM_SALES_EXP
WHERE TO_DATE(PRD_CODE,'YYYYMM') BETWEEN AS_FR_DATE AND SYSDATE
AND TERR_CODE = AS_TERR_CODE;
IF TARGET_VAL_CNT > 0 AND TARGET_VAL > 0 THEN
FINAL_VAL := ( ( SALES_VAL / NO_OF_SE ) / ( TARGET_VAL / NO_OF_SE ) ) * 100 ;
END IF;
RETURN FINAL_VAL;
END;
/
create or replace FUNCTION FN_GET_CHC_KPI_PMPM (AS_OPT CHAR, AS_SALES_PERS VARCHAR, AS_DATE DATE)
RETURN NUMBER
IS
FINAL_VAL NUMBER (14,3);
BEGIN
IF AS_OPT = 'MTD' THEN
FINAL_VAL:= 0;
END IF;
IF AS_OPT = 'YTD' THEN
FINAL_VAL:= 0;
END IF;
RETURN FINAL_VAL;
END;
/
create or replace FUNCTION FN_GET_CHC_SALES_PERF (AS_OPT CHAR, AS_SALES_PERS VARCHAR)
RETURN NUMBER
IS
FINAL_VAL NUMBER (14,3);
BEGIN
IF AS_OPT = 'OVERALL_PERCENT' THEN
FINAL_VAL:= 85;
END IF;
IF AS_OPT = 'PERCENTILE' THEN
FINAL_VAL:= 4;
END IF;
RETURN FINAL_VAL;
END;
/
-- CHC Sales Performance PACKAGE and TYPES
create TYPE ChcSalesPerfDmMaster
AS
OBJECT
(
FLD_NAME VARCHAR2(20),
DATA_GRP VARCHAR2(20),
TARGET_VALUE VARCHAR2(20), -- FLD_VALUE
ACTUAL_VALUE NUMBER(14,3), -- Calculated
DESCR VARCHAR2(120),
SH_DESCR VARCHAR2(30),
THEME_COLOR VARCHAR2(30), -- UDF_STR1
ICON VARCHAR2(30), -- UDF_STR2
WEIGHTAGE_VALUE NUMBER(14,3) -- UDF_STR3
);
/
create TYPE ChcSalesPerfTABLE
AS TABLE OF ChcSalesPerfDmMaster;
/
create or replace PACKAGE ChcSalesPerfDm
AS FUNCTION getChcSalesPerfData (empCode in char, prdCode in char)
RETURN ChcSalesPerfTABLE PIPELINED;
END ChcSalesPerfDm;
/
create or replace PACKAGE BODY ChcSalesPerfDm
AS FUNCTION getChcSalesPerfData (empCode in char, prdCode in char)
RETURN ChcSalesPerfTABLE PIPELINED IS
BEGIN
for x in (
-----------------------------------------------------------------SUMMARY-----------------------------------------------
SELECT FLD_NAME, DATA_GRP, TARGET_VALUE, ACTUAL_VALUE, DESCR, SH_DESCR, THEME_COLOR, ICON, WEIGHTAGE_VALUE
FROM
(
SELECT FLD_NAME,
'SALES_SUMMARY' AS DATA_GRP,
FLD_VALUE AS TARGET_VALUE,
CASE
WHEN TRIM(FLD_NAME) = 'SALES_TC' THEN NVL(FN_GET_CHC_KPI_TC('YTD',empCode,TO_DATE(prdCode, 'YYYYMM')),0)
WHEN TRIM(FLD_NAME) = 'SALES_PC' THEN NVL(FN_GET_CHC_KPI_PC('YTD',empCode,TO_DATE(prdCode, 'YYYYMM')),0)
WHEN TRIM(FLD_NAME) = 'SALES_FW' THEN NVL(FN_GET_CHC_KPI_FW('YTD',empCode,TO_DATE(prdCode, 'YYYYMM')),0)
WHEN TRIM(FLD_NAME) = 'SALES_ACHIVMNT' THEN NVL(FN_GET_CHC_KPI_SALES_ACHIVMNT('YTD',empCode),0)
WHEN TRIM(FLD_NAME) = 'SALES_GROWTH' THEN NVL(FN_GET_CHC_KPI_GROWTH('YTD',empCode,TO_DATE(prdCode, 'YYYYMM')),0)
WHEN TRIM(FLD_NAME) = 'SALES_PMPM' THEN NVL(FN_GET_CHC_KPI_PMPM('YTD',empCode,TO_DATE(prdCode, 'YYYYMM')),0)
ELSE 0
END AS ACTUAL_VALUE,
DESCR,
SH_DESCR,
UDF_STR1 AS THEME_COLOR,
UDF_STR2 AS ICON,
UDF_STR3 AS WEIGHTAGE_VALUE
FROM GENCODES
WHERE MOD_NAME = 'W_CHC_SALES_PERF_DM'
)
)
LOOP
PIPE ROW (ChcSalesPerfDmMaster( x.FLD_NAME, x.DATA_GRP, nvl( x.TARGET_VALUE, '0'), nvl( x.ACTUAL_VALUE, 0), x.DESCR, x.SH_DESCR, x.THEME_COLOR, x.ICON, x.WEIGHTAGE_VALUE ));
END LOOP;
RETURN;
END;
END ChcSalesPerfDm;
/
\ 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