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
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