Commit ba06a145 authored by prumde's avatar prumde

Added for DWH Data population for Sales Information

git-svn-id: http://15.206.35.175/svn/proteus/business-java/trunk@212046 ce508802-f39f-4f6c-b175-0d175dae99d5
parent 88b2057b
CREATE TABLE SUNERP.DWH_INV_SRET_SUM
(
TRAN_DATE DATE NOT NULL,
EMP_CODE CHAR(10) NOT NULL,
DIV_CODE VARCHAR2(20) NOT NULL,
DIV VARCHAR2(20),
ZONE_CODE CHAR(5) NOT NULL,
ZONE VARCHAR2(40),
REGION_CODE CHAR(5) NOT NULL,
REGION VARCHAR2(40),
AREA_CODE CHAR(5) NOT NULL,
AREA VARCHAR2(40),
TERRITORY_CODE CHAR(5) NOT NULL,
TERRITORY VARCHAR2(40),
NO_OF_SE NUMBER(3),
SITE_CODE CHAR(10) NOT NULL,
SITE_CITY VARCHAR2(20),
STATION VARCHAR2(40) NOT NULL,
BRAND_CODE VARCHAR2(5) NOT NULL,
BRAND_NAME VARCHAR2(120),
NET_QTY NUMBER(14,3),
NET_VAL NUMBER(14,3),
SALES_QTY NUMBER(14,3),
SALES_VAL NUMBER(14,3),
RETURN_QTY NUMBER(14,3),
RETURN_VAL NUMBER(14,3),
REPLACEMENT_QTY NUMBER(14,3),
REPLACEMENT_VAL NUMBER(14,3),
FREE_QTY NUMBER(14,3),
FREE_VAL NUMBER(14,3)
);
ALTER TABLE SUNERP.DWH_INV_SRET_SUM
ADD CONSTRAINT DWH_INV_SRET_SUM_PK PRIMARY KEY (TRAN_DATE, EMP_CODE, DIV_CODE, ZONE_CODE, REGION_CODE, AREA_CODE, TERRITORY_CODE, SITE_CODE, BRAND_CODE);
CREATE PROCEDURE SUNERP.DWH_INV_SRET(
AS_FR_DATE DATE,
AS_TO_DATE DATE,
AS_ITEM_SER CHAR)
AS
BEGIN
IF (AS_TO_DATE >= AS_FR_DATE) THEN
/*========== DELETE for DWH_INV_SRET_SUM Started ==========*/
DELETE FROM DWH_INV_SRET_SUM WHERE TRAN_DATE BETWEEN AS_FR_DATE AND AS_TO_DATE;
COMMIT ;
/*========== INSERT for DWH_INV_SRET_SUM End ==========*/
/*========== INSERT for DWH_INV_SRET_SUM Started ==========*/
INSERT
INTO DWH_INV_SRET_SUM
(
TRAN_DATE ,
EMP_CODE,
DIV_CODE ,
DIV ,
ZONE_CODE ,
ZONE ,
REGION_CODE ,
REGION ,
AREA_CODE ,
AREA ,
TERRITORY_CODE ,
TERRITORY ,
NO_OF_SE ,
SITE_CODE ,
SITE_CITY ,
STATION ,
BRAND_CODE ,
BRAND_NAME ,
NET_QTY ,
NET_VAL ,
SALES_QTY ,
SALES_VAL ,
RETURN_QTY ,
RETURN_VAL,
REPLACEMENT_QTY ,
REPLACEMENT_VAL,
FREE_QTY ,
FREE_VAL
)
WITH
ORG AS
(
SELECT EMP_CODE,
VERSION_ID,
TABLE_NO,
POOL_CODE AS LEVEL_CODE,
LEVEL_NO,
DESCR
FROM
(
SELECT *
FROM ORG_STRUCTURE A
WHERE A.VERSION_ID = (SELECT MAX(Q.VERSION_ID) FROM VERSION Q WHERE TRUNC(SYSDATE) BETWEEN Q.EFF_FROM AND Q.VALID_UPTO)
AND A.TABLE_NO = AS_ITEM_SER
AND A.ACTIVE = 'Y'
) ORG_STRUCTURE
START WITH ORG_STRUCTURE.POS_CODE in(
SELECT ( CASE WHEN J.STATE_CODE = 'XX' THEN 'ABC' ELSE Q.POS_CODE END ) AS POS_CODE
FROM EMPLOYEE Q,
STATION J
WHERE Q.EMP_CODE in (select emp_code from sales_pers where item_ser = 'CHC')
AND Q.POS_CODE IS NOT NULL
AND Q.STAN_CODE__HQ = J.STAN_CODE
)
CONNECT BY PRIOR ORG_STRUCTURE.POS_CODE = ORG_STRUCTURE.POS_CODE__REPTO
),
STN AS
(
SELECT X.VERSION_ID,
X.TABLE_NO,
X.EMP_CODE,
A.LEVEL_CODE AS ZONE_CODE,
A.LEVEL_DESCR AS ZONE_DESCR,
B.LEVEL_CODE AS REGION_CODE,
B.LEVEL_DESCR AS REGION_DESCR,
C.LEVEL_CODE AS AREA_CODE,
C.LEVEL_DESCR AS AREA_DESCR ,
D.LEVEL_CODE AS TERR_CODE,
D.LEVEL_DESCR AS TERR_DESCR,
D.SANC_STRENGTH,
E.STAN_CODE AS STATION_CODE ,
E.LEVEL_DESCR AS STATION_DESCR,
E.STAN_CODE
FROM HIERARCHY A,
HIERARCHY B,
HIERARCHY C,
HIERARCHY D,
HIERARCHY E,
STATION F,
(
SELECT VERSION_ID,
TABLE_NO,
LEVEL_CODE,
EMP_CODE
FROM ORG
WHERE LEVEL_NO = 4
GROUP BY VERSION_ID,
TABLE_NO,
LEVEL_CODE,
EMP_CODE
) X
WHERE E.TABLE_NO = X.TABLE_NO
AND E.VERSION_ID = X.VERSION_ID
AND E.LEVEL_NO = 5
AND D.TABLE_NO = E.TABLE_NO
AND D.VERSION_ID = E.VERSION_ID
AND D.LEVEL_NO = 4
AND D.LEVEL_CODE = E.LEVEL_CODE__PARENT
AND C.TABLE_NO = D.TABLE_NO
AND C.VERSION_ID = D.VERSION_ID
AND C.LEVEL_NO = 3
AND C.LEVEL_CODE = D.LEVEL_CODE__PARENT
AND B.TABLE_NO = C.TABLE_NO
AND B.VERSION_ID = C.VERSION_ID
AND B.LEVEL_NO = 2
AND B.LEVEL_CODE = C.LEVEL_CODE__PARENT
AND A.TABLE_NO = B.TABLE_NO
AND A.VERSION_ID = B.VERSION_ID
AND A.LEVEL_NO = 1
AND A.LEVEL_CODE = B.LEVEL_CODE__PARENT
AND F.STAN_CODE = E.STAN_CODE
AND 1 = (
CASE
WHEN (A.LEVEL_CODE = X.LEVEL_CODE
OR B.LEVEL_CODE = X.LEVEL_CODE
OR C.LEVEL_CODE = X.LEVEL_CODE
OR D.LEVEL_CODE = X.LEVEL_CODE
OR E.LEVEL_CODE = X.LEVEL_CODE)
THEN 1
ELSE 0
END
)
)
SELECT
INV_SRET.TRAN_DATE AS TRAN_DATE,
NVL(HIERARCHY.EMP_CODE,'VAC') AS EMP_CODE,
INV_SRET.INVOICE_ITEM_SER AS DIV_CODE,
MAX((SELECT Q.SH_DESCR FROM ITEMSER Q WHERE Q.ITEM_SER = INV_SRET.INVOICE_ITEM_SER )) AS DIV,
NVL(HIERARCHY.ZONE_CODE,'NA') AS ZONE_CODE,
HIERARCHY.ZONE_DESCR AS ZONE,
NVL(HIERARCHY.REGION_CODE,'NA') AS REGION_CODE,
HIERARCHY.REGION_DESCR AS REGION,
NVL(HIERARCHY.AREA_CODE,'NA') AS AREA_CODE,
HIERARCHY.AREA_DESCR AS AREA,
NVL(HIERARCHY.TERR_CODE,'NA') AS TERRITORY_CODE,
NVL(HIERARCHY.TERR_DESCR,'UN ATTACHED TERRITORY') AS TERRITORY,
HIERARCHY.SANC_STRENGTH AS NO_OF_SE,
INV_SRET.SITE_CODE AS SITE_CODE,
INV_SRET.SITE_CITY AS SITE_CITY,
MAX((SELECT DESCR FROM STATION WHERE STAN_CODE = INV_SRET.CUST_STAN_CODE)) AS STATION,
INV_SRET.SGRP_CODE AS BRAND_CODE,
GENCODES.DESCR AS BRAND_NAME,
SUM(NVL(INV_SRET.SALES_QTY,0)+NVL(INV_SRET.RETURN_QTY,0)+NVL(INV_SRET.REPLACEMENT_QTY,0)) AS NET_QTY,
SUM(NVL(INV_SRET.SALES_VAL,0)+NVL(INV_SRET.RETURN_VAL,0)+NVL(INV_SRET.REPLACEMENT_VAL,0)) AS NET_VAL,
SUM(NVL(INV_SRET.SALES_QTY,0)) AS SALES_QTY,
SUM(NVL(INV_SRET.SALES_VAL,0)) AS SALES_VAL,
SUM(NVL(INV_SRET.RETURN_QTY,0)) AS RETURN_QTY,
SUM(NVL(INV_SRET.RETURN_VAL,0)) AS RETURN_VAL,
SUM(NVL(INV_SRET.REPLACEMENT_QTY,0)) AS REPLACEMENT_QTY,
SUM(NVL(INV_SRET.REPLACEMENT_VAL,0)) AS REPLACEMENT_VAL,
SUM(NVL(INV_SRET.F_QTY,0)) AS FREE_QTY,
SUM(NVL(INV_SRET.F_AMOUNT,0)) AS FREE_VAL
FROM
(
SELECT INVOICE.TRAN_DATE AS TRAN_DATE,
INVOICE.SITE_CODE AS SITE_CODE,
SITE.CITY AS SITE_CITY,
CUSTOMER.CUST_CODE,
CUSTOMER.CUST_NAME,
CUSTOMER.STAN_CODE AS CUST_STAN_CODE,
ITEM.SGRP_CODE AS SGRP_CODE,
INVOICE_TRACE.ITEM_CODE AS ITEM_CODE,
ITEM.DESCR AS ITEM_DESCR,
ITEM.ITEM_SER AS INVOICE_ITEM_SER,
SUM (INVOICE_TRACE.QUANTITY__STDUOM) AS SALES_QTY,
SUM ((INVOICE_TRACE.QUANTITY__STDUOM * INVOICE_TRACE.RATE__STDUOM) - (((INVOICE_TRACE.QUANTITY__STDUOM * INVOICE_TRACE.RATE__STDUOM) * INVOICE_TRACE.DISCOUNT)/100)) AS SALES_VAL,
SUM(0) AS RETURN_QTY,
SUM(0) AS RETURN_VAL,
SUM(0) AS REPLACEMENT_QTY,
SUM(0) AS REPLACEMENT_VAL,
SUM (
CASE
WHEN INVOICE_TRACE.LINE_TYPE = 'F'
THEN INVOICE_TRACE.QUANTITY__STDUOM
END) AS F_QTY,
SUM (
CASE
WHEN INVOICE_TRACE.LINE_TYPE = 'F'
THEN ((INVOICE_TRACE.QUANTITY__STDUOM * INVOICE_TRACE.RATE__STDUOM) - (((INVOICE_TRACE.QUANTITY__STDUOM * INVOICE_TRACE.RATE__STDUOM) * INVOICE_TRACE.DISCOUNT) / 100))
END) AS F_AMOUNT
FROM INVOICE,
INVOICE_TRACE,
ITEM,
SITE,
SITE_CUSTOMER,
CUSTOMER,
STN
WHERE (INVOICE.INVOICE_ID = INVOICE_TRACE.INVOICE_ID)
AND (INVOICE_TRACE.ITEM_CODE = ITEM.ITEM_CODE)
AND (INVOICE.SITE_CODE = SITE_CUSTOMER.SITE_CODE)
AND (INVOICE.CUST_CODE = SITE_CUSTOMER.CUST_CODE)
AND (INVOICE.CUST_CODE = CUSTOMER.CUST_CODE)
AND (INVOICE.SITE_CODE = SITE.SITE_CODE)
AND (NVL (SITE_CUSTOMER.CHANNEL_PARTNER, 'N') = 'N')
AND (CUSTOMER.CUST_TYPE IN ('T', 'I'))
AND (ITEM.ITEM_SER IN ('RA','RG','CHC','AN','AR','AL','BR','CK','CN','CF','CL','GS','IN','MM', 'PC','PN','ST','SN','SF','SS','VG','ZO','OD','OE','HT','NS','CU','AT','SP','RN','US','ZT','AP','TR','PL','NT','RD','OT','OL', 'MT','IS','EX','CD','VE','UT','TV','AV','OP','OC' ))
AND CUSTOMER.STAN_CODE = STN.STATION_CODE
AND (INVOICE.TRAN_DATE >= AS_FR_DATE )
AND (INVOICE.TRAN_DATE <= AS_TO_DATE )
AND 1 = NVL(
(SELECT MAX(1) AS cc
FROM NSRNO J
WHERE ((J.ADATE = AS_FR_DATE) OR (J.ADATE = AS_TO_DATE))
AND AS_FR_DATE >= TRUNC(SYSDATE-35)
),0)
AND (ITEM.ITEM_SER = STN.TABLE_NO)
GROUP BY INVOICE.TRAN_DATE,
INVOICE.SITE_CODE,
SITE.CITY,
SITE.AREA_CODE,
ITEM.SGRP_CODE,
INVOICE_TRACE.ITEM_CODE,
ITEM.DESCR,
ITEM.ITEM_SER,
CUSTOMER.CUST_CODE,
CUSTOMER.CUST_NAME,
CUSTOMER.STAN_CODE
UNION ALL
SELECT SRETURN.TRAN_DATE AS TRAN_DATE,
SRETURN.SITE_CODE AS SITE_CODE,
SITE.CITY AS SITE_CITY,
CUSTOMER.CUST_CODE,
CUSTOMER.CUST_NAME,
CUSTOMER.STAN_CODE AS CUST_STAN_CODE,
ITEM.SGRP_CODE AS SGRP_CODE,
SRETURNDET.ITEM_CODE AS ITEM_CODE,
ITEM.DESCR AS ITEM_DESCR,
ITEM.ITEM_SER AS INVOICE_ITEM_SER,
SUM (0) AS SALES_QTY,
SUM (0) AS SALES_VAL,
SUM((
CASE
WHEN SRETURNDET.RET_REP_FLAG = 'P'
THEN 0
ELSE SRETURNDET.QUANTITY__STDUOM * -1
END)) AS RETURN_QTY,
SUM((
CASE
WHEN SRETURNDET.RET_REP_FLAG = 'P'
THEN 0
ELSE (((SRETURNDET.QUANTITY__STDUOM * SRETURNDET.RATE__STDUOM) - (((SRETURNDET.QUANTITY__STDUOM * SRETURNDET.RATE__STDUOM) * SRETURNDET.DISCOUNT)/100)) * -1)
END)) AS RETURN_VAL,
SUM((
CASE
WHEN SRETURNDET.RET_REP_FLAG = 'P'
THEN SRETURNDET.QUANTITY__STDUOM * 1
ELSE 0
END)) AS REPLACEMENT_QTY,
SUM((
CASE
WHEN SRETURNDET.RET_REP_FLAG = 'P'
THEN (((SRETURNDET.QUANTITY__STDUOM * SRETURNDET.RATE__STDUOM) - (((SRETURNDET.QUANTITY__STDUOM * SRETURNDET.RATE__STDUOM) * SRETURNDET.DISCOUNT)/100)) * 1)
ELSE 0
END)) AS REPLACEMENT_VAL,
SUM (
CASE
WHEN SRETURNDET.LINE_TYPE = 'F'
THEN SRETURNDET.QUANTITY__STDUOM * (
CASE
WHEN SRETURNDET.RET_REP_FLAG = 'P'
THEN 1
ELSE -1
END)
END) AS F_QTY,
SUM (
CASE
WHEN SRETURNDET.LINE_TYPE = 'F'
THEN ((SRETURNDET.QUANTITY__STDUOM * SRETURNDET.RATE__STDUOM) - (((SRETURNDET.QUANTITY__STDUOM * SRETURNDET.RATE__STDUOM) * SRETURNDET.DISCOUNT)/ 100)) * (
CASE
WHEN SRETURNDET.RET_REP_FLAG = 'P'
THEN 1
ELSE -1
END)
END) AS F_AMOUNT
FROM SRETURN,
SRETURNDET,
SITE,
ITEM,
CUSTOMER,
STN
WHERE (SRETURNDET.TRAN_ID = SRETURN.TRAN_ID)
AND (SRETURNDET.ITEM_CODE = ITEM.ITEM_CODE)
AND (SRETURN.CUST_CODE = CUSTOMER.CUST_CODE)
AND (SRETURN.SITE_CODE = SITE.SITE_CODE)
AND (NVL (CUSTOMER.CHANNEL_PARTNER, 'N') = 'N')
AND (CUSTOMER.CUST_TYPE IN ('T', 'I'))
AND CUSTOMER.STAN_CODE = STN.STATION_CODE
AND (ITEM.ITEM_SER IN ('RA','RG','CHC','AN','AR','AL','BR','CK','CN','CF','CL','GS','IN','MM', 'PC','PN','ST','SN','SF','SS','VG','ZO','OD','OE','HT','NS','CU','AT','SP','RN','US','ZT','AP','TR','PL','NT','RD','OT','OL',
'MT','IS','EX','CD','VE','UT','TV','AV','OP','OC'))
AND (SRETURN.CONFIRMED = 'Y')
AND (SRETURN.TRAN_DATE >= AS_FR_DATE)
AND (SRETURN.TRAN_DATE <= AS_TO_DATE)
AND 1 =NVL(
(SELECT MAX(1) AS cc
FROM NSRNO J
WHERE ((J.ADATE = AS_FR_DATE)
OR (J.ADATE = AS_TO_DATE))
AND AS_FR_DATE >= TRUNC(SYSDATE-35)
),0)
AND (ITEM.ITEM_SER = STN.TABLE_NO)
GROUP BY SRETURN.TRAN_DATE,
SRETURN.SITE_CODE,
SITE.CITY,
SITE.AREA_CODE,
ITEM.SGRP_CODE,
SRETURNDET.ITEM_CODE,
ITEM.DESCR,
ITEM.ITEM_SER,
CUSTOMER.CUST_CODE,
CUSTOMER.CUST_NAME,
CUSTOMER.STAN_CODE
) INV_SRET
LEFT OUTER JOIN --FOLLOWING PART IS FOR HIERARCHY and BRAND DESCRIPTION
(
SELECT EMP_CODE,
STATION_CODE,
STATION_DESCR,
TABLE_NO,
STAN_CODE,
TERR_CODE,
TERR_DESCR,
SANC_STRENGTH,
AREA_CODE,
AREA_DESCR,
REGION_CODE,
REGION_DESCR,
ZONE_CODE,
ZONE_DESCR
FROM STN
) HIERARCHY ON INV_SRET.INVOICE_ITEM_SER = HIERARCHY.TABLE_NO AND INV_SRET.CUST_STAN_CODE = HIERARCHY.STAN_CODE AND HIERARCHY.EMP_CODE IS NOT NULL
LEFT OUTER JOIN
(
SELECT FLD_VALUE,
DESCR
FROM GENCODES
WHERE FLD_NAME = 'SGRP_CODE'
) GENCODES ON INV_SRET.SGRP_CODE = GENCODES.FLD_VALUE
GROUP BY INV_SRET.TRAN_DATE,
INV_SRET.INVOICE_ITEM_SER,
INV_SRET.SITE_CODE,
INV_SRET.SITE_CITY ,
NVL(HIERARCHY.ZONE_CODE,'NA'),
HIERARCHY.ZONE_DESCR,
NVL(HIERARCHY.REGION_CODE,'NA'),
HIERARCHY.REGION_DESCR,
NVL(HIERARCHY.AREA_CODE,'NA'),
HIERARCHY.AREA_DESCR,
NVL(HIERARCHY.TERR_CODE,'NA'),
NVL(HIERARCHY.TERR_DESCR,'UN ATTACHED TERRITORY'),
HIERARCHY.SANC_STRENGTH,
NVL(HIERARCHY.EMP_CODE,'VAC'),
INV_SRET.SGRP_CODE,
GENCODES.DESCR;
COMMIT ;
/* ==================== DWH_INV_SRET_SUM Data Updation END ==================== */
END IF;
EXCEPTION
WHEN OTHERS THEN
dbms_output.put_line(' Error occured ');
END;
/
set serveroutput on
EXEC SUNERP.DWH_INV_SRET('01-NOV-19','05-NOV-19','CHC');
EXEC SUNERP.DWH_INV_SRET('05-NOV-19','10-NOV-19','CHC');
EXEC SUNERP.DWH_INV_SRET('11-NOV-19','15-NOV-19','CHC');
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