Commit 2990d663 authored by pborate's avatar pborate

Data model sql for sales trend, sales trend by month and procedure sql

git-svn-id: http://15.206.35.175/svn/proteus/business-java/trunk@199689 ce508802-f39f-4f6c-b175-0d175dae99d5
parent e72f108b
PL SQL : DWH_SALES
create or replace PROCEDURE DWH_SALES( create or replace PROCEDURE DWH_SALES(
AS_FR_DATE DATE, AS_FR_DATE DATE,
AS_TO_DATE DATE) AS_TO_DATE DATE)
AS AS
AS_ACT_KEY VARCHAR2(8);
AS_ACT_TIMESTAMP TIMESTAMP;
AS_DSS_TIMESTAMP TIMESTAMP;
AS_CNT NUMBER(10);
BEGIN BEGIN
IF (AS_TO_DATE >= AS_FR_DATE) THEN IF (AS_TO_DATE >= AS_FR_DATE) THEN
/*========== INSERT for DWH_SALES Started ==========*/ /*========== INSERT for DWH_SALES_SUM Started ==========*/
INSERT INSERT
INTO DWH_SALES_SUM INTO DWH_SALES_SUM
( (
SITE_CODE, TRAN_ID,
CUST_CODE, SITE_CODE,
ITEM_CODE, CUST_CODE,
DOC_DATE, ITEM_CODE,
SALES_QTY, DOC_DATE,
GROSS_SALES_VALUE, POS_CODE,
FREE_QTY, SALES_QTY,
FREE_SALES_VALUE, GROSS_SALES_VALUE,
NET_SALES_VALUE FREE_QTY,
) FREE_SALES_VALUE,
SELECT DS.SITE_CODE, NET_SALES_QTY,
DC.CUST_CODE, NET_SALES_VALUE,
DP.ITEM_CODE, REPL_QTY,
A.TRAN_DATE, REPL_VALUE,
SUM( COALESCE(A.SALES_QTY, 0) ), SALEABLE_RETURN_QTY,
SUM( COALESCE(A.GROSS_SALES_VALUE, 0) ), SALEABLE_RETURN_AMT,
SUM( COALESCE(A.FREE_QTY, 0) ), BREAKAGE_RETURN_QTY,
SUM( COALESCE(A.FREE_SALES_VALUE, 0) ), BREAKAGE_RETURN_AMT,
SUM( COALESCE(A.NET_SALES_VALUE, 0) ) EXPIRY_RETURN_QTY,
FROM EXPIRY_RETURN_AMT,
(SELECT INVOICE.SITE_CODE, CORRECTION_RETURN_QTY,
INVOICE.CUST_CODE, CORRECTION_RETURN_AMT,
INVOICE_TRACE.ITEM_CODE, REPL_RETURN_QTY,
INVOICE.TRAN_DATE, REPL_RETURN_VALUE,
(CASE RETURN_QTY,
WHEN COALESCE(INVOICE_TRACE.LINE_TYPE,'C') = 'F' AND INVOICE_TRACE.RATE__STDUOM = 0 THEN 0 GROSS_RETURN_VALUE,
ELSE INVOICE_TRACE.QUANTITY__STDUOM NET_RETURN_VALUE,
END) AS SALES_QTY, CGST_RATE,
(CASE CGST_AMT,
WHEN COALESCE(INVOICE_TRACE.LINE_TYPE,'C') = 'F' AND INVOICE_TRACE.RATE__STDUOM = 0 THEN 0 SGST_RATE,
ELSE INVOICE_TRACE.QUANTITY__STDUOM * INVOICE_TRACE.RATE__STDUOM SGST_AMT,
END) AS GROSS_SALES_VALUE, IGST_RATE,
(CASE IGST_AMT,
WHEN COALESCE(INVOICE_TRACE.LINE_TYPE,'C') = 'F' AND INVOICE_TRACE.RATE__STDUOM = 0 THEN INVOICE_TRACE.QUANTITY__STDUOM DISC_AMT,
ELSE 0 MRP,
END) AS FREE_QTY, PTR,
(CASE PTS,
WHEN COALESCE(INVOICE_TRACE.LINE_TYPE,'C') = 'F' AND INVOICE_TRACE.RATE__STDUOM = 0 THEN INVOICE_TRACE.QUANTITY__STDUOM * INVOICE_TRACE.RATE__STDUOM HSN_CODE,
ELSE 0 PACK,
END) AS FREE_SALES_VALUE, DUE_DATE,
INVOICE_TRACE.NET_AMT AS NET_SALES_VALUE REF_SER,
FROM INVOICE CITY,
INNER JOIN INVOICE_TRACE ITEM_BRAND,
ON INVOICE.INVOICE_ID = INVOICE_TRACE.INVOICE_ID ITEM_SER
INNER JOIN SITE )
ON INVOICE.SITE_CODE = SITE.SITE_CODE SELECT DSSV.TRAN_ID,
INNER JOIN SORDER DSSV.SITE_CODE AS SITE_CODE,
ON INVOICE.SALE_ORDER = SORDER.SALE_ORDER DSSV.CUST_CODE AS CUST_CODE,
INNER JOIN ITEM DSSV.ITEM_CODE AS ITEM_CODE,
ON INVOICE_TRACE.ITEM_CODE = ITEM.ITEM_CODE DSSV.TRAN_DATE AS DOC_DATE,
WHERE INVOICE.CONFIRMED = 'Y' NVL((SELECT ORG.POS_CODE
AND INVOICE_TRACE.ITEM_CODE BETWEEN '00' AND 'ZZ' FROM ORG_STRUCTURE_CUST ORG
AND INVOICE.TRAN_DATE >= AS_FR_DATE WHERE ORG.CUST_CODE=DSSV.CUST_CODE
AND INVOICE.TRAN_DATE <= AS_TO_DATE AND ORG.VERSION_ID IN (SELECT V.VERSION_ID FROM VERSION V WHERE TO_DATE(SYSDATE) BETWEEN V.EFF_FROM AND V.VALID_UPTO)
) A AND ORG.TABLE_NO = DSSV.ITEM_SER
LEFT OUTER JOIN SITE DS ) ,'NA') AS POS_CODE,
ON A.SITE_CODE = DS.SITE_CODE SUM( DSSV.SALES_QTY ) AS SALES_QTY,
LEFT OUTER JOIN CUSTOMER DC SUM( DSSV.GROSS_SALES_VALUE - DSSV.DISC_AMT_INV ) AS GROSS_SALES_VALUE,
ON A.CUST_CODE = DC.CUST_CODE SUM( DSSV.FREE_QTY ) AS FREE_QTY,
LEFT OUTER JOIN ITEM DP SUM( DSSV.FREE_SALES_VALUE ) AS FREE_SALES_VALUE,
ON A.ITEM_CODE = DP.ITEM_CODE SUM( DSSV.SALES_QTY + DSSV.FREE_QTY + DSSV.REPL_QTY - DSSV.RETURN_QTY + DSSV.REPL_RETURN_QTY ) AS NET_SALES_QTY,
GROUP BY DS.SITE_CODE, SUM( DSSV.GROSS_SALES_VALUE - DSSV.DISC_AMT_INV - DSSV.GROSS_RETURN_VALUE - DSSV.DISC_AMT_RET + DSSV.REPL_RETURN_VALUE - DSSV.DISC_AMT_REPL_RET) AS NET_SALES_VALUE,
DC.CUST_CODE, SUM( DSSV.REPL_QTY ) AS REPL_QTY,
DP.ITEM_CODE, SUM( DSSV.REPL_VALUE - DSSV.DISC_AMT_REPL) AS REPL_VALUE,
A.TRAN_DATE, SUM( DSSV.SALEABLE_RETURN_QTY ) AS SALEABLE_RETURN_QTY,
COALESCE(AS_DSS_TIMESTAMP, TO_TIMESTAMP(TO_CHAR(SYSTIMESTAMP,'DD-MON-YY HH24:MI:SS'),'DD-MON-YY HH24:MI:SS')), SUM( DSSV.SALEABLE_RETURN_AMT ) AS SALEABLE_RETURN_AMT,
TO_TIMESTAMP(TO_CHAR(SYSTIMESTAMP,'DD-MON-YYYY HH24:MI:SS'),'DD-MON-YYYY HH24:MI:SS') , SUM( DSSV.BREAKAGE_RETURN_QTY ) AS BREAKAGE_RETURN_QTY,
TO_CHAR(A.TRAN_DATE, 'YYYYMM') ; SUM( DSSV.BREAKAGE_RETURN_AMT ) AS BREAKAGE_RETURN_AMT,
/*========== INSERT for DWH_SALES Ended ==========*/ SUM( DSSV.EXPIRY_RETURN_QTY ) AS EXPIRY_RETURN_QTY,
SUM( DSSV.EXPIRY_RETURN_AMT ) AS EXPIRY_RETURN_AMT,
SUM( DSSV.CORRECTION_RETURN_QTY ) AS CORRECTION_RETURN_QTY,
SUM( DSSV.CORRECTION_RETURN_AMT ) AS CORRECTION_RETURN_AMT,
SUM( DSSV.REPL_RETURN_QTY ) AS REPL_RETURN_QTY,
SUM( DSSV.REPL_RETURN_VALUE - DSSV.DISC_AMT_REPL_RET) AS REPL_RETURN_VALUE,
SUM( DSSV.RETURN_QTY ) AS RETURN_QTY,
SUM( DSSV.GROSS_RETURN_VALUE - DSSV.DISC_AMT_RET) AS GROSS_RETURN_VALUE,
SUM( DSSV.NET_RETURN_VALUE ) AS NET_RETURN_VALUE,
DSSV.CGST_RATE,
SUM(DSSV.CGST_AMT) AS CGST_AMT,
DSSV.SGST_RATE,
SUM(DSSV.SGST_AMT) AS SGST_AMT,
DSSV.IGST_RATE,
SUM(DSSV.IGST_AMT) AS IGST_AMT,
SUM(DSSV.DISC_AMT_INV + DSSV.DISC_AMT_RET + DSSV.DISC_AMT_REPL + DSSV.DISC_AMT_REPL_RET) AS DISC_AMT,
DSSV.MRP,
DSSV.PTR,
DSSV.PTS,
DSSV.HSN_CODE,
(SELECT DESCR FROM PACKING WHERE PACK_CODE = DSSV.PACK_CODE) AS PACK,
DSSV.DUE_DATE,
DSSV.REF_SER,
DSSV.CITY,
DSSV.ITEM_BRAND,
DSSV.ITEM_SER
FROM
(SELECT 'S-INV ' AS REF_SER,
ITEM.ITEM_SER,
INVOICE.INVOICE_ID AS TRAN_ID,
INVOICE.SITE_CODE,
INVOICE.CUST_CODE,
INVOICE_TRACE.ITEM_CODE,
INVOICE.TRAN_DATE,
INVOICE.INV_TYPE AS TRAN_TYPE,
ITEM.HSN_NO AS HSN_CODE,
ITEM.PACK_CODE AS PACK_CODE,
DC.CITY AS CITY,
ITEM.PHY_ATTRIB_2 AS ITEM_BRAND,
TO_CHAR(INVOICE.DUE_DATE) AS DUE_DATE,
(
CASE
WHEN COALESCE(INVOICE_TRACE.LINE_TYPE,'C') IN ( 'F', 'V') AND INVOICE_TRACE.RATE__STDUOM = 0
THEN 0
ELSE INVOICE_TRACE.QUANTITY__STDUOM
END
) AS SALES_QTY,
(
CASE
WHEN COALESCE(INVOICE_TRACE.LINE_TYPE,'C') = 'F' AND INVOICE_TRACE.RATE__STDUOM = 0
THEN 0
ELSE INVOICE_TRACE.QUANTITY__STDUOM * INVOICE_TRACE.RATE__STDUOM
END
) AS GROSS_SALES_VALUE,
(
CASE
WHEN COALESCE(INVOICE_TRACE.LINE_TYPE,'C') IN ( 'I', 'V')
THEN INVOICE_TRACE.QUANTITY__STDUOM
ELSE 0
END
) AS REPL_QTY,
(
CASE
WHEN COALESCE(INVOICE_TRACE.LINE_TYPE,'C') = 'F' AND INVOICE_TRACE.RATE__STDUOM = 0
THEN INVOICE_TRACE.QUANTITY__STDUOM
ELSE 0
END
) AS FREE_QTY,
(
CASE
WHEN COALESCE(INVOICE_TRACE.LINE_TYPE,'C') = 'F' AND INVOICE_TRACE.RATE__STDUOM = 0
THEN INVOICE_TRACE.QUANTITY__STDUOM * NVL(FN_RPICK_RATE_PL(DC.PRICE_LIST, INVOICE.TRAN_DATE, INVOICE_TRACE.ITEM_CODE, INVOICE_TRACE.LOT_NO) , 0 )
ELSE 0
END
) AS FREE_SALES_VALUE,
(
CASE
WHEN COALESCE(INVOICE_TRACE.LINE_TYPE,'C') IN ( 'I', 'V') AND INVOICE_TRACE.RATE__STDUOM = 0
THEN INVOICE_TRACE.QUANTITY__STDUOM * NVL(FN_RPICK_RATE_PL(DC.PRICE_LIST, INVOICE.TRAN_DATE, INVOICE_TRACE.ITEM_CODE, INVOICE_TRACE.LOT_NO) , 0 )
ELSE 0
END
) AS REPL_VALUE,
INVOICE_TRACE.NET_AMT AS NET_SALES_VALUE,
0 AS SALEABLE_RETURN_QTY,
0 AS SALEABLE_RETURN_AMT,
0 AS BREAKAGE_RETURN_QTY,
0 AS BREAKAGE_RETURN_AMT,
0 AS EXPIRY_RETURN_QTY,
0 AS EXPIRY_RETURN_AMT,
0 AS CORRECTION_RETURN_QTY,
0 AS CORRECTION_RETURN_AMT,
0 AS REPL_RETURN_QTY,
0 AS REPL_RETURN_VALUE,
0 AS RETURN_QTY,
0 AS GROSS_RETURN_VALUE,
0 AS NET_RETURN_VALUE,
0 AS FREE_RETURN_QTY,
0 AS FREE_RET_VALUE,
NVL(FN_RGET_TAX_NEW('S-INV',INVOICE_TRACE.INVOICE_ID,CAST(INVOICE_TRACE.LINE_NO AS CHAR(3)),'CGST_TAX',' ',' ','P'),0) AS CGST_RATE,
NVL(FN_RGET_TAX_NEW('S-INV',INVOICE_TRACE.INVOICE_ID,CAST(INVOICE_TRACE.LINE_NO AS CHAR(3)),'CGST_TAX',' ',' ','T'),0) AS CGST_AMT,
NVL(FN_RGET_TAX_NEW('S-INV',INVOICE_TRACE.INVOICE_ID,CAST(INVOICE_TRACE.LINE_NO AS CHAR(3)),'SGST_TAX',' ',' ','P'),0) AS SGST_RATE,
NVL(FN_RGET_TAX_NEW('S-INV',INVOICE_TRACE.INVOICE_ID,CAST(INVOICE_TRACE.LINE_NO AS CHAR(3)),'SGST_TAX',' ',' ','T'),0) AS SGST_AMT,
NVL(FN_RGET_TAX_NEW('S-INV',INVOICE_TRACE.INVOICE_ID,CAST(INVOICE_TRACE.LINE_NO AS CHAR(3)),'IGST_TAX',' ',' ','P'),0) AS IGST_RATE,
NVL(FN_RGET_TAX_NEW('S-INV',INVOICE_TRACE.INVOICE_ID,CAST(INVOICE_TRACE.LINE_NO AS CHAR(3)),'IGST_TAX',' ',' ','T'),0) AS IGST_AMT,
( (NVL((((NVL(INVOICE_TRACE.QUANTITY,0)*NVL(INVOICE_TRACE.RATE__STDUOM,0)*NVL(INVOICE.EXCH_RATE,0))*NVL(INVOICE_TRACE.DISCOUNT,0))/100),0) + NVL(FN_RGET_TAX_NEW('S-INV', INVOICE_TRACE.INVOICE_ID, CAST(INVOICE_TRACE.LINE_NO AS CHAR(3)),'DISC_GST',' ',' ','T')*(-1),0)) ) AS DISC_AMT_INV,
0 AS DISC_AMT_RET,
(
CASE
WHEN COALESCE(INVOICE_TRACE.LINE_TYPE,'C') IN ( 'I', 'V') AND INVOICE_TRACE.RATE__STDUOM = 0
THEN ( (NVL((((NVL(INVOICE_TRACE.QUANTITY,0)*NVL(INVOICE_TRACE.RATE__STDUOM,0)*NVL(INVOICE.EXCH_RATE,0))*NVL(INVOICE_TRACE.DISCOUNT,0))/100),0)
+ NVL(FN_RGET_TAX_NEW('S-INV', INVOICE_TRACE.INVOICE_ID, CAST(INVOICE_TRACE.LINE_NO AS CHAR(3)),'DISC_GST',' ',' ','T')*(-1),0)) )
ELSE 0
END
) AS DISC_AMT_REPL,
0 AS DISC_AMT_REPL_RET,
NVL(FN_RPICK_MRP_PTR(INVOICE_TRACE.ITEM_CODE,INVOICE.TRAN_DATE,INVOICE_TRACE.LOT_NO,'MRP_GST'),0) AS MRP,
NVL(FN_RPICK_MRP_PTR(INVOICE_TRACE.ITEM_CODE,INVOICE.TRAN_DATE,INVOICE_TRACE.LOT_NO,'PTR_GST'),0) AS PTR,
NVL(INVOICE_TRACE.RATE__STDUOM,0) * NVL(INVOICE_TRACE.EXCH_RATE,0) AS PTS
FROM INVOICE
INNER JOIN INVOICE_TRACE ON INVOICE.INVOICE_ID = INVOICE_TRACE.INVOICE_ID
INNER JOIN SITE ON INVOICE.SITE_CODE = SITE.SITE_CODE
INNER JOIN ITEM ON INVOICE_TRACE.ITEM_CODE = ITEM.ITEM_CODE
LEFT OUTER JOIN CUSTOMER DC ON INVOICE.CUST_CODE = DC.CUST_CODE
WHERE INVOICE.CONFIRMED = 'Y'
AND INVOICE.TRAN_DATE >= AS_FR_DATE
AND INVOICE.TRAN_DATE <= AS_TO_DATE
UNION ALL
SELECT 'S-RET' AS REF_SER,
ITEM.ITEM_SER,
SRETURN.TRAN_ID,
SRETURN.SITE_CODE,
SRETURN.CUST_CODE,
SRETURNDET.ITEM_CODE,
SRETURN.TRAN_DATE,
SRETURN.TRAN_TYPE,
ITEM.HSN_NO AS HSN_CODE,
ITEM.PACK_CODE AS PACK_CODE,
ITEM.PHY_ATTRIB_2 AS ITEM_BRAND,
DC.CITY AS CITY,
'' DUE_DATE,
0 AS SALES_QTY,
0 AS GROSS_SALES_VALUE,
0 AS REPL_QTY,
0 AS FREE_QTY,
0 AS FREE_SALES_VALUE,
0 AS REPL_VALUE,
0 AS NET_SALES_VALUE,
(
CASE
WHEN SRETURNDET.RET_REP_FLAG = 'R'
AND SRETURN.TRAN_TYPE IN('SR')
THEN DECODE(INVOICE_TRACE.INVOICE_ID, NULL, SRETURNDET.QUANTITY__STDUOM, (
CASE
WHEN COALESCE(INVOICE_TRACE.LINE_TYPE,'C') = 'F'
AND INVOICE_TRACE.RATE__STDUOM = 0
THEN 0
ELSE SRETURNDET.QUANTITY__STDUOM
END) )
ELSE 0
END) AS SALEABLE_RETURN_QTY,
(
CASE
WHEN SRETURNDET.RET_REP_FLAG = 'R'
AND SRETURN.TRAN_TYPE IN('SR')
THEN DECODE(INVOICE_TRACE.INVOICE_ID, NULL, SRETURNDET.QUANTITY__STDUOM * SRETURNDET.RATE__STDUOM, (
CASE
WHEN COALESCE(INVOICE_TRACE.LINE_TYPE,'C') = 'F'
AND INVOICE_TRACE.RATE__STDUOM = 0
THEN 0
ELSE SRETURNDET.QUANTITY__STDUOM * INVOICE_TRACE.RATE__STDUOM
END) )
ELSE 0
END) AS SALEABLE_RETURN_AMT,
(
CASE
WHEN SRETURNDET.RET_REP_FLAG = 'R'
AND SRETURN.TRAN_TYPE IN('BR', 'DR')
THEN DECODE(INVOICE_TRACE.INVOICE_ID, NULL, SRETURNDET.QUANTITY__STDUOM, (
CASE
WHEN COALESCE(INVOICE_TRACE.LINE_TYPE,'C') = 'F'
AND INVOICE_TRACE.RATE__STDUOM = 0
THEN 0
ELSE SRETURNDET.QUANTITY__STDUOM
END) )
ELSE 0
END) AS BREAKAGE_RETURN_QTY,
(
CASE
WHEN SRETURNDET.RET_REP_FLAG = 'R'
AND SRETURN.TRAN_TYPE IN('BR', 'DR')
THEN DECODE(INVOICE_TRACE.INVOICE_ID, NULL, SRETURNDET.QUANTITY__STDUOM * SRETURNDET.RATE__STDUOM, (
CASE
WHEN COALESCE(INVOICE_TRACE.LINE_TYPE,'C') = 'F'
AND INVOICE_TRACE.RATE__STDUOM = 0
THEN 0
ELSE SRETURNDET.QUANTITY__STDUOM * INVOICE_TRACE.RATE__STDUOM
END) )
ELSE 0
END) AS BREAKAGE_RETURN_AMT,
(
CASE
WHEN SRETURNDET.RET_REP_FLAG = 'R'
AND SRETURN.TRAN_TYPE = 'ER'
AND SRETURNDET.DISCOUNT <> 100
THEN DECODE(INVOICE_TRACE.INVOICE_ID, NULL, SRETURNDET.QUANTITY__STDUOM, (
CASE
WHEN COALESCE(INVOICE_TRACE.LINE_TYPE,'C') = 'F'
AND INVOICE_TRACE.RATE__STDUOM = 0
THEN 0
ELSE SRETURNDET.QUANTITY__STDUOM
END) )
ELSE 0
END) AS EXPIRY_RETURN_QTY,
(
CASE
WHEN SRETURNDET.RET_REP_FLAG = 'R'
AND SRETURN.TRAN_TYPE = 'ER'
AND SRETURNDET.DISCOUNT <> 100
THEN DECODE(INVOICE_TRACE.INVOICE_ID, NULL, SRETURNDET.QUANTITY__STDUOM * SRETURNDET.RATE__STDUOM, (
CASE
WHEN COALESCE(INVOICE_TRACE.LINE_TYPE,'C') = 'F'
AND INVOICE_TRACE.RATE__STDUOM = 0
THEN 0
ELSE SRETURNDET.QUANTITY__STDUOM * INVOICE_TRACE.RATE__STDUOM
END) )
ELSE 0
END) AS EXPIRY_RETURN_AMT,
(
CASE
WHEN SRETURNDET.RET_REP_FLAG = 'R'
AND SRETURN.TRAN_TYPE IN('IC')
THEN DECODE(INVOICE_TRACE.INVOICE_ID, NULL, SRETURNDET.QUANTITY__STDUOM, (
CASE
WHEN COALESCE(INVOICE_TRACE.LINE_TYPE,'C') = 'F'
AND INVOICE_TRACE.RATE__STDUOM = 0
THEN 0
ELSE SRETURNDET.QUANTITY__STDUOM
END) )
ELSE 0
END) AS CORRECTION_RETURN_QTY,
(
CASE
WHEN SRETURNDET.RET_REP_FLAG = 'R'
AND SRETURN.TRAN_TYPE IN('IC')
THEN DECODE(INVOICE_TRACE.INVOICE_ID, NULL, SRETURNDET.QUANTITY__STDUOM * SRETURNDET.RATE__STDUOM, (
CASE
WHEN COALESCE(INVOICE_TRACE.LINE_TYPE,'C') = 'F'
AND INVOICE_TRACE.RATE__STDUOM = 0
THEN 0
ELSE SRETURNDET.QUANTITY__STDUOM * INVOICE_TRACE.RATE__STDUOM
END) )
ELSE 0
END) AS CORRECTION_RETURN_AMT,
DECODE(SRETURNDET.RET_REP_FLAG, 'P', SRETURNDET.QUANTITY__STDUOM, 0) AS REPL_RETURN_QTY,
DECODE(SRETURNDET.RET_REP_FLAG, 'P', SRETURNDET.QUANTITY__STDUOM * SRETURNDET.RATE__STDUOM, 0) AS REPL_RETURN_VALUE,
(
CASE
WHEN SRETURNDET.RET_REP_FLAG = 'R'
THEN DECODE(INVOICE_TRACE.INVOICE_ID, NULL, SRETURNDET.QUANTITY__STDUOM, (
CASE
WHEN COALESCE(INVOICE_TRACE.LINE_TYPE,'C') = 'F'
AND INVOICE_TRACE.RATE__STDUOM = 0
THEN 0
ELSE SRETURNDET.QUANTITY__STDUOM
END) )
ELSE 0
END) AS RETURN_QTY,
(
CASE
WHEN SRETURNDET.RET_REP_FLAG = 'R'
THEN DECODE(INVOICE_TRACE.INVOICE_ID, NULL, SRETURNDET.QUANTITY__STDUOM * SRETURNDET.RATE__STDUOM, (
CASE
WHEN COALESCE(INVOICE_TRACE.LINE_TYPE,'C') = 'F'
AND INVOICE_TRACE.RATE__STDUOM = 0
THEN 0
ELSE SRETURNDET.QUANTITY__STDUOM * INVOICE_TRACE.RATE__STDUOM
END) )
ELSE 0
END) AS GROSS_RETURN_VALUE,
SRETURNDET.NET_AMT AS NET_RETURN_VALUE,
(
CASE
WHEN SRETURNDET.RET_REP_FLAG = 'R'
THEN DECODE(INVOICE_TRACE.INVOICE_ID, NULL, 0, (
CASE
WHEN COALESCE(INVOICE_TRACE.LINE_TYPE,'C') = 'F'
AND INVOICE_TRACE.RATE__STDUOM = 0
THEN SRETURNDET.QUANTITY__STDUOM
ELSE 0
END) )
ELSE 0
END) AS FREE_RETURN_QTY,
(CASE
WHEN SRETURNDET.RET_REP_FLAG = 'R'
THEN DECODE(INVOICE_TRACE.INVOICE_ID, NULL, 0, (
CASE
WHEN COALESCE(INVOICE_TRACE.LINE_TYPE,'C') = 'F'
AND INVOICE_TRACE.RATE__STDUOM = 0
THEN SRETURNDET.QUANTITY__STDUOM * INVOICE_TRACE.RATE__STDUOM
ELSE 0
END) )
ELSE 0
END) AS FREE_RET_VALUE,
NVL(FN_RGET_TAX_NEW('S-RET',SRETURN.TRAN_ID,CAST(SRETURNDET.LINE_NO AS CHAR(3)),'CGST_TAX',' ',' ','P'),0) AS CGST_RATE,
NVL(FN_RGET_TAX_NEW('S-RET',SRETURN.TRAN_ID,CAST(SRETURNDET.LINE_NO AS CHAR(3)),'CGST_TAX',' ',' ','T'),0) AS CGST_AMT,
NVL(FN_RGET_TAX_NEW('S-RET',SRETURN.TRAN_ID,CAST(SRETURNDET.LINE_NO AS CHAR(3)),'SGST_TAX',' ',' ','P'),0) AS SGST_RATE,
NVL(FN_RGET_TAX_NEW('S-RET',SRETURN.TRAN_ID,CAST(SRETURNDET.LINE_NO AS CHAR(3)),'SGST_TAX',' ',' ','T'),0) AS SGST_AMT,
NVL(FN_RGET_TAX_NEW('S-RET',SRETURN.TRAN_ID,CAST(SRETURNDET.LINE_NO AS CHAR(3)),'IGST_TAX',' ',' ','P'),0) AS IGST_RATE,
NVL(FN_RGET_TAX_NEW('S-RET',SRETURN.TRAN_ID,CAST(SRETURNDET.LINE_NO AS CHAR(3)),'IGST_TAX',' ',' ','T'),0) AS IGST_AMT,
0 AS DISC_AMT_INV,
((NVL((((NVL(SRETURNDET.QUANTITY,0)*NVL(SRETURNDET.RATE__STDUOM,0)*NVL(SRETURN.EXCH_RATE,0))*NVL(SRETURNDET.DISCOUNT,0))/100),0)
+ NVL(FN_RGET_TAX_NEW('S-RET', SRETURN.TRAN_ID, CAST(SRETURNDET.LINE_NO AS CHAR(3)),'DISC_GST',' ',' ','T')*(-1),0))) AS DISC_AMT_RET,
0 AS DISC_AMT_REPL,
DECODE(SRETURNDET.RET_REP_FLAG,'P',((NVL((((NVL(SRETURNDET.QUANTITY,0)*NVL(SRETURNDET.RATE__STDUOM,0)*NVL(SRETURN.EXCH_RATE,0))*NVL(SRETURNDET.DISCOUNT,0))/100),0)
+ NVL(FN_RGET_TAX_NEW('S-RET', SRETURN.TRAN_ID, CAST(SRETURNDET.LINE_NO AS CHAR(3)),'DISC_GST',' ',' ','T')*(-1),0))), 0) AS DISC_AMT_REPL_RET,
NVL(FN_RPICK_MRP_PTR(SRETURNDET.ITEM_CODE, SRETURN.TRAN_DATE,SRETURNDET.LOT_NO,'MRP_GST'),0) AS MRP,
NVL(FN_RPICK_MRP_PTR(SRETURNDET.ITEM_CODE, SRETURN.TRAN_DATE,SRETURNDET.LOT_NO,'PTR_GST'),0) AS PTR,
NVL(SRETURNDET.RATE__STDUOM,0) * NVL(SRETURN.EXCH_RATE,0) AS PTS
FROM SRETURN
INNER JOIN SRETURNDET ON SRETURN.TRAN_ID = SRETURNDET.TRAN_ID
INNER JOIN SITE ON SRETURN.SITE_CODE = SITE.SITE_CODE
INNER JOIN ITEM ON SRETURNDET.ITEM_CODE = ITEM.ITEM_CODE
LEFT OUTER JOIN CUSTOMER DC ON SRETURN.CUST_CODE = DC.CUST_CODE
LEFT OUTER JOIN INVOICE_TRACE ON SRETURN.INVOICE_ID = INVOICE_TRACE.INVOICE_ID
AND SRETURNDET.INVOICE_ID = INVOICE_TRACE.INVOICE_ID
AND SRETURNDET.LINE_NO__INVTRACE = INVOICE_TRACE.LINE_NO
WHERE SRETURN.CONFIRMED = 'Y'
AND SRETURN.TRAN_DATE >= AS_FR_DATE
AND SRETURN.TRAN_DATE <= AS_TO_DATE
) DSSV
GROUP BY DSSV.TRAN_ID,
DSSV.SITE_CODE,
DSSV.CUST_CODE,
DSSV.ITEM_CODE,
DSSV.TRAN_DATE,
DSSV.MRP,
DSSV.PTR,
DSSV.PTS,
DSSV.HSN_CODE,
DSSV.PACK_CODE,
DSSV.DUE_DATE,
DSSV.ITEM_BRAND,
DSSV.CITY,
DSSV.CGST_RATE,
DSSV.SGST_RATE,
DSSV.IGST_RATE,
DSSV.REF_SER,
DSSV.ITEM_SER ;
/*========== INSERT for DWH_SALES_SUM Ended ==========*/
COMMIT ; COMMIT ;
/* ==================== DWH_SALES Data Insertion END ==================== */ /* ==================== DWH_SALES_SUM Data Insertion END ==================== */
END IF; END IF;
END; END;
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) values ('SALES_ANALYSIS_BY_MONTH','SALES ANALYSIS DATA','S','
select DSS.DOC_DATE as "TRANSACTION DATE",
DSS.POS_CODE as "LEVEL CODE",
NVL(DHH.lv4,''NA'') as "LEVEL1 CODE",
NVL(DHH.lv4_descr,''NA'') as "LEVEL1 DESCRIPTION",
NVL(DHH.lv3,''NA'') as "LEVEL2 CODE",
NVL(DHH.lv3_descr,''NA'') as "LEVEL2 DESCRIPTION",
NVL(DHH.lv2,''NA'') as "LEVEL3 CODE",
NVL(DHH.lv2_descr,''NA'') as "LEVEL3 DESCRIPTION",
NVL(DHH.lv1,''NA'') as "LEVEL4 CODE",
NVL(DHH.lv1_descr,''NA'') as "LEVEL4 DESCRIPTION",
NVL(DHH.POS_CODE,''NA'') as "POSITION CODE",
DHH.POOL_CODE as "POOL CODE",
DHH.TABLE_NO as "TABLE NO",
DHH.VERSION_ID as "VERSION ID",
DSS.CUST_CODE as "CUSTOMER CODE",
(SELECT CUST_NAME from CUSTOMER where CUST_CODE = DSS.CUST_CODE) as "CUSTOMER NAME",
DSS.SITE_CODE as "SITE CODE",
(SELECT DESCR from SITE where SITE_CODE = DSS.SITE_CODE) as "SITE DESCRIPTION",
DSS.ITEM_CODE AS "ITEM CODE", I.DESCR AS "ITEM DESCRIPTION",
I.ITEM_SER as "ITEM SERIES",
ISER.DESCR as "ITEM SERIES DESCRIPTION",
ISER.PRODUCT_LINE as "PRODUCT LINE",
(SELECT descr from GENCODES where RPAD(fld_value, 5, '' '') = ISER.PRODUCT_LINE) as "PRODUCT LINE DESCRIPTION",
DSS.NET_SALES_VALUE as "NET SALES VALUE",
DSS.SALES_QTY as "SALES QUANTITY",
DSS.GROSS_SALES_VALUE as "GROSS SALES VALUE",
DSS.FREE_QTY as "FREE QUANTITY",
DSS.FREE_SALES_VALUE as "FREE SALES VALUE",
DSS.NET_SALES_QTY as "NET SALES QUANTITY",
DSS.REPL_VALUE as "REPLACEMENT VALUE",
DSS.SALEABLE_RETURN_QTY as "SALEABLE RETURN QUANTITY",
DSS.SALEABLE_RETURN_AMT as "SALEABLE RETURN VALUE",
DSS.BREAKAGE_RETURN_QTY as "DAMAGED RETURN QUANTITY",
DSS.BREAKAGE_RETURN_AMT as "DAMAGED RETURN VALUE",
DSS.EXPIRY_RETURN_QTY as "EXPIRY RETURN QUANTITY",
DSS.EXPIRY_RETURN_AMT as "EXPIRY RETURN VALUE",
DSS.CORRECTION_RETURN_QTY as "CANCELED RETURN QUANTITY",
DSS.CORRECTION_RETURN_AMT as "CANCELED RETURN VALUE",
DSS.REPL_RETURN_QTY as "REPLACEMENT RETURN QUANTITY",
DSS.REPL_RETURN_VALUE as "REPLACEMENT RETURN VALUE",
DSS.RETURN_QTY as "RETURN QUANTITY",
DSS.GROSS_RETURN_VALUE as "GROSS RETURN VALUE",
DSS.NET_RETURN_VALUE as "NET RETURN VALUE" ,
DSS.TRAN_ID,
DSS.REPL_QTY as "REPLACEMENT QUANTITY",
DSS.DISC_AMT,
DSS.MRP,
DSS.PTR,
DSS.PTS,
DSS.HSN_CODE,
DSS.PACK,
DUE_DATE,
DSS.CGST_AMT,
DSS.CGST_RATE,
DSS.SGST_RATE,
DSS.SGST_AMT,
DSS.CITY,
DSS.ITEM_BRAND,
DSS.IGST_AMT,
DSS.IGST_RATE,
DSS.REF_SER
from DWH_SALES_SUM DSS
LEFT OUTER JOIN ITEM I ON DSS.ITEM_CODE = I.ITEM_CODE
LEFT OUTER JOIN ITEMSER ISER ON I.ITEM_SER = ISER.ITEM_SER
LEFT OUTER JOIN
(
select lv1.pos_code lv1,lv1.pos_code__repto lv1_repo,lv1.descr as lv1_descr,
lv2.pos_code lv2,lv2.pos_code__repto lv2_repo,lv2.descr as lv2_descr,
lv3.pos_code lv3,lv3.pos_code__repto lv3_repo,lv3.descr as lv3_descr,
lv4.pos_code lv4,lv4.pos_code__repto lv4_repo,lv4.descr as lv4_descr,
lv1.pos_code,lv1.table_no,lv1.version_id,lv1.pool_code
from org_structure lv1
left outer join org_structure lv2 on lv1.pos_code__repto=lv2.pos_code
left outer join org_structure lv3 on lv2.pos_code__repto=lv3.pos_code
left outer join org_structure lv4 on lv3.pos_code__repto=lv4.pos_code
) DHH ON
DHH.POS_CODE = DSS.POS_CODE
AND DHH.version_id in (select version_id from version where to_date(sysdate) between eff_from and valid_upto )
WHERE to_char(DSS.DOC_DATE, ''MM/YYYY'')= ?
AND I.ITEM_SER >= ?
AND I.ITEM_SER <= ?
AND DSS.SITE_CODE = ?',
':MONTH,:ITEM_SER__FR,:ITEM_SER__TO,:SITE_CODE_TO','json',SYSDATE,'ADMIN','SYSTEM',null,
'MONTH'||'&'||'ITEM_SER__FR'||'&'||'ITEM_SER__TO'||'&'||'SITE_CODE_TO',null);
\ No newline at end of file
delete from DATA_MODEL where DATA_MODEL = 'SALES_ANALYSIS';
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)
values ('SALES_ANALYSIS','SALES ANALYSIS DATA','S',
'select DS.DOC_DATE as "TRANSACTION DATE",
DS.POS_CODE as "LEVEL CODE",
NVL(DH.lv4,''NA'') as "LEVEL1 CODE",
NVL(DH.lv4_descr,''NA'') as "LEVEL1 DESCRIPTION",
NVL(DH.lv3,''NA'') as "LEVEL2 CODE",
NVL(DH.lv3_descr,''NA'') as "LEVEL2 DESCRIPTION",
NVL(DH.lv2,''NA'') as "LEVEL3 CODE",
NVL(DH.lv2_descr,''NA'') as "LEVEL3 DESCRIPTION",
NVL(DH.lv1,''NA'') as "LEVEL4 CODE",
NVL(DH.lv1_descr,''NA'') as "LEVEL4 DESCRIPTION",
NVL(DH.POS_CODE,''NA'') as "POSITION CODE",
DH.POOL_CODE as "POOL CODE",
DH.TABLE_NO as "TABLE NO",
DH.VERSION_ID as "VERSION ID",
DS.CUST_CODE as "CUSTOMER CODE",
(SELECT CUST_NAME from CUSTOMER where CUST_CODE=DS.CUST_CODE) as "CUSTOMER NAME",
DS.SITE_CODE as "SITE CODE",
(SELECT DESCR from SITE where SITE_CODE=DS.SITE_CODE) as "SITE DESCRIPTION",
DS.ITEM_CODE AS "ITEM CODE",
I.DESCR AS "ITEM DESCRIPTION",
I.ITEM_SER as "ITEM SERIES",
ISER.DESCR as "ITEM SERIES DESCRIPTION",
ISER.PRODUCT_LINE as "PRODUCT LINE",
(SELECT descr from GENCODES where RPAD(fld_value,5,'' '')=ISER.PRODUCT_LINE) as "PRODUCT LINE DESCRIPTION",
DS.NET_SALES_VALUE as "NET SALES VALUE",
DS.SALES_QTY as "SALES QUANTITY",
DS.GROSS_SALES_VALUE as "GROSS SALES VALUE",
DS.FREE_QTY as "FREE QUANTITY",
DS.FREE_SALES_VALUE as "FREE SALES VALUE",
DS.NET_SALES_QTY as "NET SALES QUANTITY",
DS.SALE_RET_QTY as "SALEABLE RETURN QUANTITY",
DS.SALE_RET_AMT as "SALEABLE RETURN VALUE",
DS.BRK_RET_QTY as "DAMAGED RETURN QUANTITY",
DS.BRK_RET_AMT as "DAMAGED RETURN VALUE",
DS.EXP_RET_QTY as "EXPIRY RETURN QUANTITY",
DS.EXP_RET_AMT as "EXPIRY RETURN VALUE",
DS.COR_RET_QTY as "CANCELED RETURN QUANTITY",
DS.COR_RET_AMT as "CANCELED RETURN VALUE",
DS.REPL_RET_QTY as "REPLACEMENT RETURN QUANTITY",
DS.REPL_RET_VALUE as "REPLACEMENT RETURN VALUE",
DS.RET_QTY as "RETURN QUANTITY",
DS.GROSS_RET_VALUE as "GROSS RETURN VALUE",
DS.NET_RET_VALUE as "NET RETURN VALUE",
DS.REPL_VALUE as "REPLACEMENT VALUE"
from
(
select
DS.DOC_DATE,
DS.POS_CODE,
DS.CUST_CODE,
DS.SITE_CODE,
DS.ITEM_CODE,
SUM(DS.NET_SALES_VALUE) as NET_SALES_VALUE,
SUM(DS.SALES_QTY) as SALES_QTY,
SUM(DS.GROSS_SALES_VALUE) as GROSS_SALES_VALUE,
SUM(DS.FREE_QTY) as FREE_QTY,
SUM(DS.FREE_SALES_VALUE) as FREE_SALES_VALUE,
SUM(DS.NET_SALES_QTY) as NET_SALES_QTY,
SUM(DS.SALEABLE_RETURN_QTY) as SALE_RET_QTY,
SUM(DS.SALEABLE_RETURN_AMT) as SALE_RET_AMT,
SUM(DS.BREAKAGE_RETURN_QTY) as BRK_RET_QTY,
SUM(DS.BREAKAGE_RETURN_AMT) as BRK_RET_AMT,
SUM(DS.EXPIRY_RETURN_QTY) as EXP_RET_QTY,
SUM(DS.EXPIRY_RETURN_AMT) as EXP_RET_AMT,
SUM(DS.CORRECTION_RETURN_QTY) as COR_RET_QTY,
SUM(DS.CORRECTION_RETURN_AMT) as COR_RET_AMT,
SUM(DS.REPL_RETURN_QTY) as REPL_RET_QTY,
SUM(DS.REPL_RETURN_VALUE) as REPL_RET_VALUE,
SUM(DS.RETURN_QTY) as RET_QTY,
SUM(DS.GROSS_RETURN_VALUE) as GROSS_RET_VALUE,
SUM(DS.NET_RETURN_VALUE) as NET_RET_VALUE,
SUM(DS.REPL_VALUE) as REPL_VALUE
from DWH_SALES_SUM DS
group by DS.SITE_CODE,DS.CUST_CODE,DS.ITEM_CODE,DS.DOC_DATE,DS.POS_CODE
) DS
LEFT OUTER JOIN ITEM I ON DS.ITEM_CODE=I.ITEM_CODE
LEFT OUTER JOIN ITEMSER ISER ON I.ITEM_SER=ISER.ITEM_SER
LEFT OUTER JOIN
(
select lv1.pos_code lv1,lv1.pos_code__repto lv1_repo,lv1.descr as lv1_descr,
lv2.pos_code lv2,lv2.pos_code__repto lv2_repo,lv2.descr as lv2_descr,
lv3.pos_code lv3,lv3.pos_code__repto lv3_repo,lv3.descr as lv3_descr,
lv4.pos_code lv4,lv4.pos_code__repto lv4_repo,lv4.descr as lv4_descr,
lv1.pos_code,lv1.table_no,lv1.version_id,lv1.pool_code
from org_structure lv1
left outer join org_structure lv2 on lv1.pos_code__repto=lv2.pos_code
left outer join org_structure lv3 on lv2.pos_code__repto=lv3.pos_code
left outer join org_structure lv4 on lv3.pos_code__repto=lv4.pos_code
)DH ON DH.POS_CODE=DS.POS_CODE
AND DH.version_id in(select version_id from version where to_date(sysdate) between eff_from and valid_upto)
WHERE DS.DOC_DATE >= ?
AND DS.DOC_DATE <= ?
AND I.ITEM_SER >= ?
AND I.ITEM_SER <= ?
AND DS.SITE_CODE >= ?
AND DS.SITE_CODE <= ?',
':fromDate,:toDate,:ITEM_SER__FR,:ITEM_SER__TO,:SITE_CODE_FR,:SITE_CODE_TO','json',SYSDATE,'ADMIN','SYSTEM',null,
'fromDate'||'&'||'toDate'||'&'||'ITEM_SER__FR'||'&'||'ITEM_SER__TO'||'&'||'SITE_CODE_FR'||'&'||'SITE_CODE_TO',null);
\ 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