Commit 693b8485 authored by prumde's avatar prumde

Added function

git-svn-id: http://15.206.35.175/svn/proteus/business-java/trunk@216260 ce508802-f39f-4f6c-b175-0d175dae99d5
parent abe888a7
......@@ -278,3 +278,75 @@ Insert into DATA_MODEL_USE (DATA_MODEL,OBJ_NAME,FORM_NAME,FIELD_NAME,IS_CRITICAL
----------RSM INSERT DM END-------------------------------------------------------------------------------
---------------FN_GET_COACH_COUNT Starts --------------------
create or replace FUNCTION FN_GET_COACH_COUNT(
as_survery_code IN CHAR,
as_sprs_code IN CHAR,
as_opt IN CHAR,
as_frm_date IN DATE,
as_to_date IN DATE)
RETURN NUMBER IS cnt NUMBER(14);
ls_count NUMBER(14);
BEGIN
IF as_opt = 'CUSTCNT' then --for attend count
SELECT COUNT(SM.STRG_CODE) INTO ls_count
FROM STRG_MEET SM, SPRS_COACHING SCOCH, SURVEY_MASTER SURVM
WHERE SM.DCR_ID = SCOCH.DCR_ID
AND SM.TRAN_ID = SCOCH.TRAN_ID
AND SM.STRG_CODE = SCOCH.STRG_CODE
AND SCOCH.SURVEY_CODE = SURVM.SURVEY_CODE
AND SURVM.RESULT_TYPE = 'L'
AND SM.EVENT_DATE BETWEEN as_frm_date AND as_to_date
AND SCOCH.SURVEY_CODE = as_survery_code
AND SCOCH.SPRS_CODE__WW = as_sprs_code;
END IF;
IF as_opt='COACHCNT' THEN --for coaching count   
SELECT COUNT(distinct SM.TRAN_ID) into ls_count
FROM STRG_MEET SM, SPRS_COACHING SCOCH, SURVEY_MASTER SURVM
WHERE SM.DCR_ID = SCOCH.DCR_ID
AND SM.TRAN_ID = SCOCH.TRAN_ID
AND SM.STRG_CODE = SCOCH.STRG_CODE
AND SCOCH.SURVEY_CODE = SURVM.SURVEY_CODE
AND SURVM.RESULT_TYPE = 'L'
AND SM.EVENT_DATE BETWEEN as_frm_date AND as_to_date
AND SCOCH.SURVEY_CODE = as_survery_code
AND SCOCH.SPRS_CODE__WW = as_sprs_code;
END IF;
IF as_opt='TOTQS' THEN --for Total Coaching Question count   
SELECT COUNT(SM.TRAN_ID) into ls_count
FROM STRG_MEET SM, SPRS_COACHING SCOCH, SURVEY_MASTER SURVM
WHERE SM.DCR_ID = SCOCH.DCR_ID
AND SM.TRAN_ID = SCOCH.TRAN_ID
AND SM.STRG_CODE = SCOCH.STRG_CODE
AND SCOCH.SURVEY_CODE = SURVM.SURVEY_CODE
AND SURVM.RESULT_TYPE = 'L'
AND SM.EVENT_DATE BETWEEN as_frm_date AND as_to_date
AND SCOCH.SURVEY_CODE = as_survery_code
AND SCOCH.SPRS_CODE__WW = as_sprs_code;
END IF;
IF as_opt='TOTYS' THEN --for Total Coaching Y's count   
SELECT COUNT(SM.TRAN_ID) into ls_count
FROM STRG_MEET SM, SPRS_COACHING SCOCH, SURVEY_MASTER SURVM
WHERE SM.DCR_ID = SCOCH.DCR_ID
AND SM.TRAN_ID = SCOCH.TRAN_ID
AND SM.STRG_CODE = SCOCH.STRG_CODE
AND SCOCH.SURVEY_CODE = SURVM.SURVEY_CODE
AND SCOCH.RESULT= SURVM.CORRECT_ANS
AND SM.EVENT_DATE BETWEEN as_frm_date AND as_to_date
AND SCOCH.SURVEY_CODE = as_survery_code
AND SCOCH.SPRS_CODE__WW = as_sprs_code;
END IF;
cnt := ls_count;
RETURN cnt;
END ;
/
---------------FN_GET_COACH_COUNT Starts --------------------
......@@ -165,3 +165,149 @@ Insert into DATA_MODEL_USE (DATA_MODEL,OBJ_NAME,FORM_NAME,FIELD_NAME,IS_CRITICAL
---------------FN_GET_USER_TASK_DESCR Starts--------------------
create or replace FUNCTION FN_GET_USER_TASK_DESCR
(
AS_USER_ID IN CHAR,
AS_USER_ID__ASSIGNED IN CHAR,
AS_REF_ID IN CHAR,
AS_REF_SER IN CHAR
)
RETURN VARCHAR2 IS AS_TASK_DESCR VARCHAR2(250);
AS_TRAN_DATE DATE;
BEGIN
SELECT MAX(TRAN_DATE) INTO AS_TRAN_DATE
FROM USER_TASKS
WHERE USER_ID = AS_USER_ID
AND USER_ID__ASSIGNED = AS_USER_ID__ASSIGNED
AND REF_ID = AS_REF_ID
AND REF_SER = AS_REF_SER
AND TRUNC(TRAN_DATE) = TRUNC(SYSDATE);
SELECT TASK_DESCR INTO AS_TASK_DESCR
FROM USER_TASKS
WHERE USER_ID = AS_USER_ID
AND USER_ID__ASSIGNED = AS_USER_ID__ASSIGNED
AND REF_ID = AS_REF_ID
AND REF_SER = AS_REF_SER
AND TRAN_DATE = AS_TRAN_DATE;
RETURN AS_TASK_DESCR;
END;
/
---------------FN_GET_USER_TASK_DESCR Ends--------------------
/****************************Package Start******************************************/
-- Package Definition
CREATE OR REPLACE PACKAGE SELL_IN_OUT_PKG
AS
FUNCTION GET_SELL_IN_OUT(AS_SALES_PERS IN CHAR)
RETURN SIO_TABLE PIPELINED;
END SELL_IN_OUT_PKG;
/
-- Package Body
create or replace PACKAGE BODY SELL_IN_OUT_PKG
AS
FUNCTION GET_SELL_IN_OUT (AS_SALES_PERS in char)
RETURN SIO_TABLE PIPELINED IS
BEGIN
for x in(
WITH
PLANNED_INOUT as ( -- Planned
SELECT
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
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
LEFT OUTER JOIN PRODUCT P ON I.PRODUCT_CODE = P.PRODUCT_CODE
WHERE SP.SALES_PERS IN (
SELECT EMP_CODE
FROM ORG_STRUCTURE O1
START WITH EMP_CODE = AS_SALES_PERS
CONNECT BY PRIOR POS_CODE = POS_CODE__REPTO
)
AND SP.PRD_CODE = (SELECT CODE FROM PERIOD WHERE SYSDATE BETWEEN FR_DATE AND TO_DATE)
AND SP.STATUS = 'S'
),
ACTUAL_INOUT as ( -- Actual
SELECT
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
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
LEFT OUTER JOIN PRODUCT P ON I.PRODUCT_CODE = P.PRODUCT_CODE
WHERE SSIO.SALES_PERS IN (
SELECT EMP_CODE
FROM ORG_STRUCTURE O1
START WITH EMP_CODE = AS_SALES_PERS
CONNECT BY PRIOR POS_CODE = POS_CODE__REPTO
)
AND SSIO.PRD_CODE = (SELECT CODE FROM PERIOD WHERE SYSDATE BETWEEN FR_DATE AND TO_DATE)
AND SSIO.STATUS = 'A'
),
ACHIEVE_INOUT as ( -- Achievement
SELECT PIO.PRODUCT_CODE,
PIO.ITEM_CODE,
PIO.SC_CODE,
PIO.SELL_IN AS PLANNED_IN,
PIO.SELL_OUT AS PLANNED_OUT,
AIO.SELL_IN AS ACTUAL_IN,
AIO.SELL_OUT AS ACTUAL_OUT,
CASE WHEN PIO.SELL_IN > 0 THEN (AIO.SELL_IN / PIO.SELL_IN) * 100 ELSE 0 END AS ACHIV_SELL_IN,
CASE WHEN PIO.SELL_OUT > 0 THEN (AIO.SELL_OUT / PIO.SELL_OUT) * 100 ELSE 0 END AS ACHIV_SELL_OUT
FROM PLANNED_INOUT PIO
LEFT OUTER JOIN ACTUAL_INOUT AIO ON PIO.SC_CODE = AIO.SC_CODE AND PIO.ITEM_CODE = AIO.ITEM_CODE
WHERE PIO.SELL_IN > 0
)
SELECT ACIO.PRODUCT_CODE,
ROUND( ( SUM(ACIO.ACHIV_SELL_IN) / COUNT(ACIO.ITEM_CODE) ) ) AS SELL_IN,
ROUND( ( SUM(ACIO.ACHIV_SELL_OUT) / COUNT(ACIO.ITEM_CODE) ) ) AS SELL_OUT
FROM ACHIEVE_INOUT ACIO
GROUP BY ACIO.PRODUCT_CODE
)
LOOP
PIPE ROW (SELL_IN_OUT_MST( x.PRODUCT_CODE, x.SELL_IN, x.SELL_OUT ));
END LOOP;
RETURN;
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