Advertisement
aadddrr

Untitled

Mar 7th, 2017
92
0
Never
Not a member of Pastebin yet? Sign Up, it unlocks many cool features!
  1. CREATE OR REPLACE FUNCTION r_sls_commission_for_igs(character varying, bigint, bigint, bigint, character varying, bigint, bigint, bigint, character varying, character varying, bigint, bigint, bigint)
  2.   RETURNS SETOF refcursor AS
  3. $BODY$
  4. DECLARE
  5.     pRefHeader              REFCURSOR := 'refHeader';
  6.     pRefDetail              REFCURSOR := 'refDetail';
  7.     pSessionId              ALIAS FOR $1;
  8.     pTenantId               ALIAS FOR $2;
  9.     pUserId                 ALIAS FOR $3;
  10.     pRoleId                 ALIAS FOR $4;
  11.     pDatetime               ALIAS FOR $5;
  12.     pOuId                   ALIAS FOR $6;
  13.     pSalesId                ALIAS FOR $7;
  14.     pYear                   ALIAS FOR $8;
  15.     pQuarterCode            ALIAS FOR $9;
  16.     pLineOfBusinessCode     ALIAS FOR $10;
  17.     pBrandId                ALIAS FOR $11;
  18.     pCtgrProductId          ALIAS FOR $12;
  19.     pSubCtgrProductId       ALIAS FOR $13;
  20.    
  21.     result                      RECORD;
  22.     vMonthFrom                  character varying(4);
  23.     vMonthTo                    character varying(4);
  24.     vDateFrom                   character varying(8);
  25.     vDateTo                     character varying(8);
  26.     vMainCoaExtCommission       character varying(10);
  27.     vSubCoaExtCommission        character varying(10);
  28.     vCurrGL                     character varying(5);
  29.     vOneMonthAfterDateTo        character varying(6);
  30.     vOneMonthBeforeDateTo       character varying(6);
  31.     vOneMonthBeforeDateFrom     character varying(6);
  32.     vComboId                    character varying := 'DIGITCURRENCY';
  33.     vCurrCodeUSD                character varying := 'USD';
  34.     vCurrCodeIDR                character varying := 'IDR';
  35.     vRoundingDigitUSD           integer;
  36.     vRoundingDigitIDR           integer;
  37.     vEmptyId                    bigint := -99;
  38.     vNol                        numeric := 0;
  39.     vOne                        numeric := 1;
  40.     vDefault                    character varying := 'DEFAULT';
  41.     vEmptyString                character varying := '';
  42.     vSpace                      character varying := ' ';
  43.    
  44.     vNo                         character varying := 'N';
  45.     vYes                        character varying := 'Y';
  46.     vStatusDocDraft             character varying := 'D';
  47.     vStatusDocRelease           character varying := 'R';
  48.     vGroupSegmentOthers         character varying := 'OTHERS';
  49.     vGroupSegmentSo             character varying := 'SO';
  50.     vTypeExcRateCom             character varying := 'COM';
  51.     vTypeExcRateTax             character varying := 'TAX';
  52.     vDocTypeSalesInvoice        bigint := 321;
  53.     vDocTypeReturnSalesInvoice  bigint := 331;
  54.     vDocTypeRg                  bigint := 111;
  55.     vPrevClosingYearMonth       character varying(6);
  56.    
  57.    
  58.     vCoaIdExtCommission         bigint;
  59.     vTwoMonthsFromDateTo        character varying(6);
  60.    
  61.     vOldTimestamp timestamp;
  62.     vNewTimestamp timestamp;
  63. BEGIN
  64.     /*
  65.      * ambil nilai date from dan date to
  66.      * ambil nilai pembulatan
  67.      * ambil nilai valuta buku
  68.      * ambil coa id
  69.      * ambil 1 bulan setelah date to dan 1 bulan sebelum date from
  70.      * delete fi_temp_summary_monthly_ar date_year_month des-apr
  71.      * insert dari fi_summary_monthly_ar
  72.      * ambil bulan terakhir tutup bulan
  73.      * menjalankan function tutup bulan sementara
  74.      * ambil data hasil tutup bulan sementara dan join ke tabel so (invoice yg pelunasannya sampe sebulan setelahnya)
  75.      * ambil data yg doc_datenya sebulan sebelum dateFrom dan pelunasannya sebulan sebelum dateTo
  76.      * update nilai price_idr
  77.      * update table temporary for numerator_rate, denominator_rate, price_idr
  78.      * update item_amount menjadi IDR
  79.      * ambil others cost
  80.      * update table cost tr_data_so_sales_for_commission non ext commission
  81.      * update table cost tr_data_so_sales_for_commission ext commission
  82.      */
  83.    
  84.     SELECT clock_timestamp() INTO vOldTimestamp;
  85.     SELECT clock_timestamp() INTO vNewTimestamp;
  86.     RAISE NOTICE 'Start at : %', vOldTimestamp;
  87.    
  88.     DELETE FROM tr_data_so_sales_commission_for_igs WHERE session_id = pSessionId;
  89.     DELETE FROM tt_warranty_sell_amount WHERE session_id = pSessionId;
  90.    
  91.     SELECT clock_timestamp() INTO vNewTimestamp;
  92.     RAISE NOTICE 'Done delete tr_data_so_sales_commission_for_igs for : %', vNewTimestamp - vOldTimestamp;
  93.     vOldTimestamp := vNewTimestamp;
  94.    
  95.     --ambil nilai dateFrom dan dateTo
  96.     SELECT month_from, month_to
  97.     FROM dt_period_quarter
  98.     WHERE quarter = pQuarterCode INTO result;
  99.     vMonthFrom := result.month_from;
  100.     vMonthTo := result.month_to;
  101.    
  102.     SELECT clock_timestamp() INTO vNewTimestamp;
  103.     RAISE NOTICE 'Done get month for : %', vNewTimestamp - vOldTimestamp;
  104.     vOldTimestamp := vNewTimestamp;
  105.    
  106.     vDateFrom := pYear || vMonthFrom;
  107.    
  108.     SELECT clock_timestamp() INTO vNewTimestamp;
  109.     RAISE NOTICE 'Done get vDateFrom for : %', vNewTimestamp - vOldTimestamp;
  110.     vOldTimestamp := vNewTimestamp;
  111.    
  112.     vDateTo := pYear || vMonthTo;
  113.    
  114.     SELECT clock_timestamp() INTO vNewTimestamp;
  115.     RAISE NOTICE 'Done get vDateTo for : %', vNewTimestamp - vOldTimestamp;
  116.     vOldTimestamp := vNewTimestamp;
  117.    
  118.     /* ambil nilai pembulatan*/
  119.     vRoundingDigitUSD := CAST(f_get_digit_decimal_currency(vComboId,vCurrCodeUSD) AS integer);
  120.    
  121.     SELECT clock_timestamp() INTO vNewTimestamp;
  122.     RAISE NOTICE 'Done get vRoundingDigitUSD for : %', vNewTimestamp - vOldTimestamp;
  123.     vOldTimestamp := vNewTimestamp;
  124.    
  125.     vRoundingDigitIDR := CAST(f_get_digit_decimal_currency(vComboId,vCurrCodeIDR) AS integer);
  126.    
  127.     SELECT clock_timestamp() INTO vNewTimestamp;
  128.     RAISE NOTICE 'Done get vRoundingDigitIDR for : %', vNewTimestamp - vOldTimestamp;
  129.     vOldTimestamp := vNewTimestamp;
  130.    
  131.     /* ambil valuta buku */
  132.     vCurrGL := f_get_value_system_config_by_param_code(pTenantId,'ValutaBuku');
  133.    
  134.     SELECT clock_timestamp() INTO vNewTimestamp;
  135.     RAISE NOTICE 'Done ambil valuta buku for : %', vNewTimestamp - vOldTimestamp;
  136.     vOldTimestamp := vNewTimestamp;
  137.    
  138.     /* ambil coa id */
  139.     vMainCoaExtCommission := f_get_value_system_config_by_param_code(pTenantId,'MainCoaExtCommission');
  140.    
  141.     SELECT clock_timestamp() INTO vNewTimestamp;
  142.     RAISE NOTICE 'Done get vMainCoaExtCommission for : %', vNewTimestamp - vOldTimestamp;
  143.     vOldTimestamp := vNewTimestamp;
  144.    
  145.     vSubCoaExtCommission := f_get_value_system_config_by_param_code(pTenantId,'SubCoaExtCommission');
  146.    
  147.     SELECT clock_timestamp() INTO vNewTimestamp;
  148.     RAISE NOTICE 'Done get vSubCoaExtCommission for : %', vNewTimestamp - vOldTimestamp;
  149.     vOldTimestamp := vNewTimestamp;
  150.    
  151.     SELECT coa_id INTO vCoaIdExtCommission
  152.     FROM m_coa
  153.     WHERE main_acc = vMainCoaExtCommission
  154.         AND sub_acc = vSubCoaExtCommission;
  155.    
  156.     SELECT clock_timestamp() INTO vNewTimestamp;
  157.     RAISE NOTICE 'Done get vCoaIdExtCommission for : %', vNewTimestamp - vOldTimestamp;
  158.     vOldTimestamp := vNewTimestamp;
  159.        
  160.     /* ambil 1 bulan setelah date to dan 1 bulan sebelum date from*/
  161.     SELECT TO_CHAR(TO_DATE(vDateTo,'YYYYMMDD') + interval '1 Month','YYYYMM') INTO vOneMonthAfterDateTo;
  162.     SELECT TO_CHAR(TO_DATE(vDateTo,'YYYYMMDD') - interval '1 Month','YYYYMM') INTO vOneMonthBeforeDateTo;
  163.     SELECT TO_CHAR(TO_DATE(vDateFrom,'YYYYMMDD') - interval '1 Month','YYYYMM') INTO vOneMonthBeforeDateFrom;
  164.    
  165.     SELECT clock_timestamp() INTO vNewTimestamp;
  166.     RAISE NOTICE 'Done ambil 1 bulan setelah date to dan 1 bulan sebelum date from for : %', vNewTimestamp - vOldTimestamp;
  167.     vOldTimestamp := vNewTimestamp;
  168.    
  169.     -- delete fi_temp_summary_monthly_ar
  170.     DELETE FROM fi_temp_summary_monthly_ar
  171.     WHERE date_year_month BETWEEN vOneMonthBeforeDateFrom AND vOneMonthAfterDateTo;
  172.    
  173.     SELECT clock_timestamp() INTO vNewTimestamp;
  174.     RAISE NOTICE 'Done delete fi_temp_summary_monthly_ar for : %', vNewTimestamp - vOldTimestamp;
  175.     vOldTimestamp := vNewTimestamp;
  176.    
  177.     --insert dari fi_summary_monthly_ar
  178.     INSERT INTO fi_temp_summary_monthly_ar(date_year_month, tenant_id, ou_id, doc_type_id, invoice_id,
  179.         invoice_amount, balance_amount, payment_amount, curr_code, version,
  180.         create_datetime, create_user_id, update_datetime, update_user_id)
  181.     SELECT A.date_year_month, A.tenant_id, A.ou_id, A.doc_type_id, A.invoice_id,
  182.         A.invoice_amount, A.balance_amount, A.payment_amount, A.curr_code, vNol,
  183.         pDatetime, pUserId, pDatetime, pUserId
  184.     FROM fi_summary_monthly_ar A
  185.     INNER JOIN m_ou_structure B ON A.ou_id = B.ou_id
  186.     WHERE A.date_year_month BETWEEN vOneMonthBeforeDateFrom AND vOneMonthAfterDateTo
  187.     AND B.ou_bu_id = pOuId;
  188.    
  189.     SELECT clock_timestamp() INTO vNewTimestamp;
  190.     RAISE NOTICE 'Done insert dari fi_summary_monthly_ar  for : %', vNewTimestamp - vOldTimestamp;
  191.     vOldTimestamp := vNewTimestamp;
  192.    
  193.     /* ambil bulan terakhir tutup bulan */
  194.     SELECT MAX(date_year_month) INTO vPrevClosingYearMonth
  195.     FROM m_admin_process_ledger
  196.     WHERE ou_id = pOuId
  197.         AND ledger_code = 'FIN.AR'
  198.         AND status_ledger = '1';
  199.        
  200.     SELECT clock_timestamp() INTO vNewTimestamp;
  201.     RAISE NOTICE 'Done ambil bulan terakhir tutup bulan  for : %', vNewTimestamp - vOldTimestamp;
  202.     vOldTimestamp := vNewTimestamp;
  203.        
  204.     /* menjalankan function tutup bulan sementara */
  205.     WHILE vPrevClosingYearMonth < vOneMonthAfterDateTo LOOP
  206.         SELECT TO_CHAR(TO_DATE(vPrevClosingYearMonth,'YYYYMM') + interval '1 Month','YYYYMM') INTO vPrevClosingYearMonth;
  207.         PERFORM fi_temp_summary_ar(pTenantId,pSessionId,pOuId,vPrevClosingYearMonth,pDatetime,pUserId);
  208.     END LOOP;
  209.    
  210.     SELECT clock_timestamp() INTO vNewTimestamp;
  211.     RAISE NOTICE 'Done tutup bulan sementara for : %', vNewTimestamp - vOldTimestamp;
  212.     vOldTimestamp := vNewTimestamp;
  213.    
  214.     --ambil data hasil tutup bulan sementara dan join ke tabel so (invoice yg pelunasannya sampe sebulan setelahnya)
  215.     WITH vw_fi_all_invoice_ar_for_commission AS (
  216.         SELECT A.invoice_ar_balance_id AS id, A.doc_type_id, A.invoice_ar_id
  217.         FROM fi_invoice_ar_balance A
  218.         INNER JOIN m_ou_structure C ON A.ou_id = C.ou_id
  219.         WHERE A.tenant_id = pTenantId
  220.         AND C.ou_bu_id = pOuId
  221.        
  222.         UNION ALL
  223.        
  224.         SELECT a.invoice_tax_ar_balance_id AS id, a.doc_type_id, b.invoice_ar_id
  225.         FROM fi_invoice_tax_ar_balance a
  226.         INNER JOIN fi_invoice_ar_balance b on a.invoice_ar_balance_id = b.invoice_ar_balance_id
  227.         INNER JOIN m_ou_structure D ON A.ou_id = D.ou_id
  228.         AND A.tenant_id = pTenantId
  229.         AND D.ou_bu_id = pOuId
  230.     )
  231.     --ambil data hasil tutup bulan sementara dan join ke tabel so (invoice yg pelunasannya sampe sebulan setelahnya)
  232.     INSERT INTO tr_data_so_sales_commission_for_igs(
  233.             session_id, tenant_id, date_year_month, invoice_id, doc_type_id,
  234.             inv_curr_code, inv_doc_no, inv_doc_date, ou_id, so_id,
  235.             so_doc_no, so_doc_date, do_id, do_item_id, original_total_amount,
  236.             so_item_id, product_id, qty_dlv_int, base_uom_id, partner_id,
  237.             salesman_id, brand_id, line_of_business, numerator_rate, denominator_rate,
  238.             original_price, total_amount_idr, total_amount_usd, other_costs, other_costs_idr,
  239.             other_costs_usd, other_costs_curr_code, other_cost_ext_commission, warranty_sell_amount)
  240.     SELECT pSessionId, pTenantId, ' ', A.invoice_id, A.doc_type_id,
  241.         A.curr_code, B.doc_no, B.doc_date, A.ou_id, B.ref_id,
  242.         G.doc_no, G.doc_date, C.ref_id, C.ref_item_id, CASE WHEN A.doc_type_id = vDocTypeReturnSalesInvoice THEN -1 * SUM(C.ref_item_amount) ELSE SUM(C.ref_item_amount) END,
  243.         F.so_item_id, F.product_id, CASE WHEN A.doc_type_id = vDocTypeReturnSalesInvoice THEN SUM(-1*(F.qty_int * D.qty_dlv_so)/F.qty_so) ELSE SUM((F.qty_int * D.qty_dlv_so)/F.qty_so) END, F.base_uom_id, G.partner_id,
  244.         G.salesman_id, I.brand_id, J.line_of_business, vOne, vOne,
  245.         vNol, vNol, vNol, vNol, vNol,
  246.         vNol, vCurrCodeIdr, vNol, vNol--CASE WHEN A.doc_type_id = vDocTypeReturnSalesInvoice THEN -1 * SUM(COALESCE(L.warranty_sell_amount, vNol)) ELSE SUM(COALESCE(L.warranty_sell_amount, vNol)) END
  247.     FROM fi_temp_summary_monthly_ar A
  248.     INNER JOIN vw_fi_all_invoice_ar_for_commission H ON A.doc_type_id = H.doc_type_id AND A.invoice_id = H.id
  249.     INNER JOIN sl_invoice B ON H.invoice_ar_id = B.invoice_id AND B.doc_type_id = H.doc_type_id
  250.     INNER JOIN sl_invoice_item C ON B.invoice_id = C.invoice_id
  251.     INNER JOIN sl_so_balance_invoice D ON B.tenant_id = D.tenant_id AND B.ou_id = D.ou_id AND B.partner_id = D.partner_id
  252.         AND C.ref_doc_type_id = D.ref_doc_type_id AND C.ref_id = D.ref_id AND C.ref_item_id = D.ref_item_id
  253.         AND C.do_receipt_item_id = D.do_receipt_item_id
  254.     INNER JOIN sl_do_item E ON C.ref_item_id = E.do_item_id
  255.     INNER JOIN sl_so_item F ON E.ref_id = F.so_item_id
  256.     INNER JOIN sl_so G ON F.so_id = G.so_id
  257.     INNER JOIN m_product I ON F.product_id = I.product_id
  258.     INNER JOIN m_partner J ON J.partner_id = G.partner_id
  259.     /*LEFT JOIN sl_so_balance_warranty_invoice L ON B.tenant_id = L.tenant_id AND L.ou_id = B.ou_id AND L.partner_id = B.partner_id
  260.         AND L.ref_doc_type_id = C.ref_doc_type_id AND L.ref_id = C.ref_id AND L.ref_item_id = C.ref_item_id
  261.         AND L.do_receipt_item_id = C.do_receipt_item_id*/
  262.     WHERE A.doc_type_id IN (vDocTypeSalesInvoice, vDocTypeReturnSalesInvoice)
  263.         AND A.date_year_month BETWEEN SUBSTRING(vDateFrom, 1, 6) AND vOneMonthAfterDateTo
  264.         AND (pSalesId = vEmptyId OR G.salesman_id = pSalesId)
  265.         AND (pBrandId = vEmptyId OR I.brand_id = pBrandId)
  266.         AND (pCtgrProductId = vEmptyId OR I.ctgr_product_id = pCtgrProductId)
  267.         AND (pSubCtgrProductId = vEmptyId OR I.sub_ctgr_product_id = pSubCtgrProductId)
  268.         AND (pLineOfBusinessCode = vEmptyString OR J.line_of_business = pLineOfBusinessCode)
  269.         AND B.doc_date BETWEEN vDateFrom and vDateTo
  270.         AND F.qty_so > 0
  271.         AND A.date_year_month = (
  272.             SELECT MAX(Z.date_year_month)
  273.             FROM fi_temp_summary_monthly_ar Z
  274.             WHERE A.invoice_id = Z.invoice_id
  275.             AND A.doc_type_id = Z.doc_type_id
  276.             AND A.ou_id = Z.ou_id
  277.             AND A.tenant_id = Z.tenant_id
  278.         )
  279.     GROUP BY A.invoice_id, A.doc_type_id, J.line_of_business, A.ou_id, A.curr_code, B.doc_no, B.doc_date, B.ref_id, C.ref_id, C.ref_item_id,
  280.         F.so_item_id, F.product_id, I.product_code, I.product_name, F.base_uom_id, G.partner_id, I.brand_id, G.salesman_id, G.doc_no, G.doc_date;
  281.        
  282.     SELECT clock_timestamp() INTO vNewTimestamp;
  283.     RAISE NOTICE 'Done insert tr_data_so_sales_commission_for_igs (1) for : %', vNewTimestamp - vOldTimestamp;
  284.     vOldTimestamp := vNewTimestamp;
  285.        
  286.     WITH vw_fi_all_invoice_ar_for_commission AS (
  287.         SELECT A.invoice_ar_balance_id AS id, A.doc_type_id, A.invoice_ar_id
  288.         FROM fi_invoice_ar_balance A
  289.         INNER JOIN m_ou_structure D ON A.ou_id = D.ou_id
  290.         WHERE A.tenant_id = pTenantId
  291.         AND D.ou_bu_id = pOuId
  292.        
  293.         UNION ALL
  294.        
  295.         SELECT a.invoice_tax_ar_balance_id AS id, a.doc_type_id, b.invoice_ar_id
  296.         FROM fi_invoice_tax_ar_balance a
  297.         INNER JOIN fi_invoice_ar_balance b on a.invoice_ar_balance_id = b.invoice_ar_balance_id
  298.         INNER JOIN m_ou_structure D ON A.ou_id = D.ou_id
  299.         AND A.tenant_id = pTenantId
  300.         AND D.ou_bu_id = pOuId
  301.     )
  302.    
  303.     --ambil data yg doc_datenya sebulan sebelum dateFrom dan pelunasannya satu bulan sebelum date to
  304.     INSERT INTO tr_data_so_sales_commission_for_igs(
  305.             session_id, tenant_id, date_year_month, invoice_id, doc_type_id,
  306.             inv_curr_code, inv_doc_no, inv_doc_date, ou_id, so_id,
  307.             so_doc_no, so_doc_date, do_id, do_item_id, original_total_amount,
  308.             so_item_id, product_id, qty_dlv_int, base_uom_id, partner_id,
  309.             salesman_id, brand_id, line_of_business, numerator_rate, denominator_rate,
  310.             original_price, total_amount_idr, total_amount_usd, other_costs, other_costs_idr,
  311.             other_costs_usd, other_costs_curr_code,other_cost_ext_commission, warranty_sell_amount)
  312.     SELECT pSessionId, pTenantId, ' ', A.invoice_id, A.doc_type_id,
  313.         A.curr_code, B.doc_no, B.doc_date, A.ou_id, B.ref_id,
  314.         G.doc_no, G.doc_date, C.ref_id, C.ref_item_id, CASE WHEN A.doc_type_id = vDocTypeReturnSalesInvoice THEN -1 * SUM(C.ref_item_amount) ELSE SUM(C.ref_item_amount) END,
  315.         F.so_item_id, F.product_id, CASE WHEN A.doc_type_id = vDocTypeReturnSalesInvoice THEN SUM(-1*(F.qty_int * D.qty_dlv_so)/F.qty_so) ELSE SUM((F.qty_int * D.qty_dlv_so)/F.qty_so) END, F.base_uom_id, G.partner_id,
  316.         G.salesman_id, I.brand_id, J.line_of_business, vOne, vOne,
  317.         vNol, vNol, vNol, vNol, vNol,
  318.         vNol, vCurrCodeIdr, vNol, vNol--CASE WHEN A.doc_type_id = vDocTypeReturnSalesInvoice THEN -1 * SUM(COALESCE(L.warranty_sell_amount, vNol)) ELSE SUM(COALESCE(L.warranty_sell_amount, vNol)) END
  319.     FROM fi_temp_summary_monthly_ar A
  320.     INNER JOIN vw_fi_all_invoice_ar_for_commission H ON A.doc_type_id = H.doc_type_id AND A.invoice_id = H.id
  321.     INNER JOIN sl_invoice B ON H.invoice_ar_id = B.invoice_id AND B.doc_type_id = H.doc_type_id
  322.     INNER JOIN sl_invoice_item C ON B.invoice_id = C.invoice_id
  323.     INNER JOIN sl_so_balance_invoice D ON B.tenant_id = D.tenant_id AND B.ou_id = D.ou_id AND B.partner_id = D.partner_id
  324.         AND C.ref_doc_type_id = D.ref_doc_type_id AND C.ref_id = D.ref_id AND C.ref_item_id = D.ref_item_id
  325.         AND C.do_receipt_item_id = D.do_receipt_item_id
  326.     INNER JOIN sl_do_item E ON C.ref_item_id = E.do_item_id
  327.     INNER JOIN sl_so_item F ON E.ref_id = F.so_item_id
  328.     INNER JOIN sl_so G ON F.so_id = G.so_id
  329.     INNER JOIN m_product I ON F.product_id = I.product_id
  330.     INNER JOIN m_partner J ON J.partner_id = G.partner_id
  331.     /*LEFT JOIN sl_so_balance_warranty_invoice L ON B.tenant_id = L.tenant_id AND L.ou_id = B.ou_id AND L.partner_id = B.partner_id
  332.         AND L.ref_doc_type_id = C.ref_doc_type_id AND L.ref_id = C.ref_id AND L.ref_item_id = C.ref_item_id
  333.         AND L.do_receipt_item_id = C.do_receipt_item_id*/
  334.     WHERE A.doc_type_id IN (vDocTypeSalesInvoice, vDocTypeReturnSalesInvoice)
  335.         AND A.date_year_month = vOneMonthBeforeDateTo
  336.         AND (pSalesId = vEmptyId OR G.salesman_id = pSalesId)
  337.         AND (pBrandId = vEmptyId OR I.brand_id = pBrandId)
  338.         AND (pCtgrProductId = vEmptyId OR I.ctgr_product_id = pCtgrProductId)
  339.         AND (pSubCtgrProductId = vEmptyId OR I.sub_ctgr_product_id = pSubCtgrProductId)
  340.         AND (pLineOfBusinessCode = vEmptyString OR J.line_of_business = pLineOfBusinessCode)
  341.         AND SUBSTRING(B.doc_date, 1, 6) = vOneMonthBeforeDateFrom
  342.         AND F.qty_so > 0
  343.         AND A.date_year_month = (
  344.             SELECT MAX(Z.date_year_month)
  345.             FROM fi_temp_summary_monthly_ar Z
  346.             WHERE A.invoice_id = Z.invoice_id
  347.             AND A.doc_type_id = Z.doc_type_id
  348.             AND A.ou_id = Z.ou_id
  349.             AND A.tenant_id = Z.tenant_id
  350.         )
  351.     GROUP BY A.invoice_id, A.doc_type_id, J.line_of_business, A.ou_id, A.curr_code, B.doc_no, B.doc_date, B.ref_id, C.ref_id, C.ref_item_id,
  352.         F.so_item_id, F.product_id, I.product_code, I.product_name, F.base_uom_id, G.partner_id, I.brand_id, G.salesman_id, G.doc_no, G.doc_date;
  353.    
  354.     SELECT clock_timestamp() INTO vNewTimestamp;
  355.     RAISE NOTICE 'Done insert tr_data_so_sales_commission_for_igs (2) for : %', vNewTimestamp - vOldTimestamp;
  356.     vOldTimestamp := vNewTimestamp;
  357.    
  358.     /*
  359.      * Adrian, Mar 7 2017
  360.      * Mennganti LEFT JOIN ke sl_so_balance_warranty_invoice menjadi update
  361.      */
  362.     /*WITH vw_warranty_sell_amount AS (
  363.         SELECT A.invoice_id, B.do_item_id,  
  364.             CASE WHEN A.doc_type_id = vDocTypeReturnSalesInvoice
  365.                 THEN -1 * SUM(L.warranty_sell_amount)  
  366.             ELSE
  367.                 SUM(L.warranty_sell_amount)
  368.             END AS sum_warranty_sell_amount
  369.         FROM tr_data_so_sales_commission_for_igs A
  370.         INNER JOIN sl_do_item B ON B.do_item_id = A.do_item_id
  371.         INNER JOIN sl_invoice_item C ON C.ref_item_id = B.do_item_id
  372.         INNER JOIN sl_invoice D ON D.invoice_id = C.invoice_id
  373.         INNER JOIN sl_so_balance_warranty_invoice L ON L.ou_id = D.ou_id AND L.partner_id = D.partner_id
  374.             AND L.ref_doc_type_id = C.ref_doc_type_id AND L.ref_id = C.ref_id AND L.ref_item_id = C.ref_item_id
  375.             AND L.do_receipt_item_id = C.do_receipt_item_id
  376.         WHERE A.session_id = pSessionId
  377.         GROUP BY A.invoice_id, A.doc_type_id, B.do_item_id
  378.     )
  379.     UPDATE tr_data_so_sales_commission_for_igs A
  380.     SET warranty_sell_amount = B.sum_warranty_sell_amount
  381.     FROM vw_warranty_sell_amount B
  382.     WHERE A.session_id = pSessionId
  383.         AND A.invoice_id = B.invoice_id
  384.         AND A.do_item_id = B.do_item_id;*/
  385.    
  386.     INSERT INTO tt_warranty_sell_amount(
  387.             session_id, invoice_id, do_item_id, sum_warranty_sell_amount
  388.         )
  389.     SELECT pSessionId, A.invoice_id, B.do_item_id,  
  390.         CASE WHEN A.doc_type_id = vDocTypeReturnSalesInvoice
  391.             THEN -1 * SUM(L.warranty_sell_amount)  
  392.         ELSE
  393.             SUM(L.warranty_sell_amount)
  394.         END AS sum_warranty_sell_amount
  395.     FROM tr_data_so_sales_commission_for_igs A
  396.     INNER JOIN sl_do_item B ON B.do_item_id = A.do_item_id
  397.     INNER JOIN sl_invoice_item C ON C.ref_item_id = B.do_item_id
  398.     INNER JOIN sl_invoice D ON D.invoice_id = C.invoice_id
  399.     INNER JOIN sl_so_balance_warranty_invoice L ON L.ou_id = D.ou_id AND L.partner_id = D.partner_id
  400.         AND L.ref_doc_type_id = C.ref_doc_type_id AND L.ref_id = C.ref_id AND L.ref_item_id = C.ref_item_id
  401.         AND L.do_receipt_item_id = C.do_receipt_item_id
  402.     WHERE A.session_id = pSessionId
  403.     GROUP BY A.invoice_id, A.doc_type_id, B.do_item_id;
  404.        
  405.     SELECT clock_timestamp() INTO vNewTimestamp;
  406.     RAISE NOTICE 'Done update tr_data_so_sales_commission_for_igs warranty sell amount for : %', vNewTimestamp - vOldTimestamp;
  407.     vOldTimestamp := vNewTimestamp;
  408.    
  409.        
  410.     /* update nilai original_price and original total_amount */
  411.     UPDATE tr_data_so_sales_commission_for_igs A
  412.     SET original_price = A.original_total_amount / A.qty_dlv_int
  413.     WHERE A.qty_dlv_int <> 0;
  414.    
  415.     SELECT clock_timestamp() INTO vNewTimestamp;
  416.     RAISE NOTICE 'Done update nilai original_price and original total_amount for : %', vNewTimestamp - vOldTimestamp;
  417.     vOldTimestamp := vNewTimestamp;
  418.        
  419.     /* update table temporary for numerator_rate, denominator_rate */
  420.     UPDATE tr_data_so_sales_commission_for_igs A
  421.     SET numerator_rate = B.amount_to,
  422.         denominator_rate = B.amount_from
  423.     FROM m_exchange_rate B
  424.     WHERE A.session_id = pSessionId
  425.         AND A.inv_doc_date = B.date_from
  426.         AND B.type_exchange_rate = vTypeExcRateCom;
  427.    
  428.     SELECT clock_timestamp() INTO vNewTimestamp;
  429.     RAISE NOTICE 'Done update table temporary for numerator_rate, denominator_rate for : %', vNewTimestamp - vOldTimestamp;
  430.     vOldTimestamp := vNewTimestamp;
  431.        
  432.     /* others cost */
  433.     INSERT INTO tr_data_costs_sales_commission_for_igs(
  434.             session_id, tenant_id, ou_id, segment_id, so_id, gl_curr_code, gl_amount,
  435.             coa_id)
  436.     SELECT pSessionId, pTenantId, A.ou_bu_id, B.segmen_id, D.so_id, B.gl_curr_code, B.gl_amount,
  437.         B.coa_id
  438.     FROM gl_journal_trx A
  439.         INNER JOIN vw_gl_journal_trx_details B ON A.journal_trx_id = B.journal_trx_id
  440.         INNER JOIN m_segment_coa C ON B.segmen_id = C.segment_coa_id
  441.         INNER JOIN tr_data_so_sales_commission_for_igs D ON C.segment_coa_code = D.so_doc_no
  442.     WHERE A.status_doc = vStatusDocRelease
  443.         AND (C.group_segment = vGroupSegmentOthers OR C.group_segment = vGroupSegmentSo)
  444.     GROUP BY  A.ou_bu_id, B.segmen_id, D.so_id, B.gl_curr_code, B.gl_amount, B.coa_id
  445.     UNION ALL
  446.     SELECT pSessionId, pTenantId, A.ou_bu_id, B.segmen_id, D.so_id, B.gl_curr_code, ROUND(B.amount * B.numerator_rate / B.denominator_rate, vRoundingDigitUSD),
  447.         B.coa_id
  448.     FROM gl_journal_trx A
  449.         INNER JOIN vw_gl_journal_trx_details B ON A.journal_trx_id = B.journal_trx_id
  450.         INNER JOIN m_segment_coa C ON B.segmen_id = C.segment_coa_id
  451.         INNER JOIN tr_data_so_sales_commission_for_igs D ON C.segment_coa_code = D.so_doc_no
  452.     WHERE A.status_doc = vStatusDocDraft
  453.         AND (C.group_segment = vGroupSegmentOthers OR C.group_segment = vGroupSegmentSo)
  454.     GROUP BY A.ou_bu_id, B.segmen_id, D.so_id, B.gl_curr_code, B.amount, B.numerator_rate, B.denominator_rate, B.coa_id;
  455.    
  456.     SELECT clock_timestamp() INTO vNewTimestamp;
  457.     RAISE NOTICE 'Done insert tr_data_costs_sales_commission_for_igs (3) other cost for : %', vNewTimestamp - vOldTimestamp;
  458.     vOldTimestamp := vNewTimestamp;
  459.    
  460.     /* update table cost tr_data_so_sales_for_commission non ext commission */
  461.     UPDATE tr_data_so_sales_commission_for_igs B
  462.     SET other_costs = (SELECT CASE WHEN B.doc_type_id = vDocTypeReturnSalesInvoice THEN 0 ELSE COALESCE(SUM(A.gl_amount),0) END
  463.     FROM tr_data_costs_sales_commission_for_igs A WHERE A.so_id = B.so_id AND A.coa_id <> vCoaIdExtCommission AND A.session_id = B.session_id)
  464.     WHERE B.session_id = pSessionId
  465.         AND B.so_item_id = (SELECT MIN(K.so_item_id) FROM sl_so_item K WHERE K.so_id = B.so_id AND K.qty_so > 0);
  466.        
  467.     SELECT clock_timestamp() INTO vNewTimestamp;
  468.     RAISE NOTICE 'Done update table cost tr_data_so_sales_for_commission non ext commission for : %', vNewTimestamp - vOldTimestamp;
  469.     vOldTimestamp := vNewTimestamp;
  470.    
  471.     /* update table cost tr_data_so_sales_for_commission ext commission */
  472.     UPDATE tr_data_so_sales_commission_for_igs B
  473.     SET other_cost_ext_commission = (SELECT COALESCE(SUM(A.gl_amount),0) FROM tr_data_costs_sales_commission_for_igs A WHERE A.so_id = B.so_id AND A.coa_id = vCoaIdExtCommission AND A.session_id = B.session_id)
  474.     WHERE B.session_id = pSessionId
  475.         AND B.so_item_id = (SELECT MIN(K.so_item_id) FROM sl_so_item K WHERE K.so_id = B.so_id AND K.qty_so > 0);
  476.        
  477.     SELECT clock_timestamp() INTO vNewTimestamp;
  478.     RAISE NOTICE 'Done update table cost tr_data_so_sales_for_commission ext commission for : %', vNewTimestamp - vOldTimestamp;
  479.     vOldTimestamp := vNewTimestamp;
  480.  
  481.     --update total_amount_usd
  482.     UPDATE tr_data_so_sales_commission_for_igs
  483.     SET total_amount_usd =
  484.         CASE WHEN inv_curr_code = 'IDR'
  485.                 THEN  (original_total_amount * denominator_rate)/numerator_rate
  486.             WHEN inv_curr_code = 'USD'
  487.                 THEN original_total_amount
  488.             ELSE vNol
  489.         END
  490.     WHERE qty_dlv_int <> 0;
  491.    
  492.     SELECT clock_timestamp() INTO vNewTimestamp;
  493.     RAISE NOTICE 'Done update total_amount_usd for : %', vNewTimestamp - vOldTimestamp;
  494.     vOldTimestamp := vNewTimestamp;
  495.    
  496.     --update total_amount_idr
  497.     UPDATE tr_data_so_sales_commission_for_igs
  498.     SET total_amount_idr = CASE WHEN inv_curr_code = 'USD'
  499.                 THEN (original_total_amount * numerator_rate)/denominator_rate
  500.              WHEN inv_curr_code = 'IDR'
  501.                 THEN original_total_amount
  502.             ELSE vNol
  503.         END
  504.     WHERE qty_dlv_int <> 0;
  505.    
  506.     SELECT clock_timestamp() INTO vNewTimestamp;
  507.     RAISE NOTICE 'Done update total_amount_idr for : %', vNewTimestamp - vOldTimestamp;
  508.     vOldTimestamp := vNewTimestamp;
  509.    
  510.     --update other_costs_usd
  511.     UPDATE tr_data_so_sales_commission_for_igs
  512.     SET other_costs_usd = (other_costs * denominator_rate)/numerator_rate
  513.     WHERE qty_dlv_int <> 0;
  514.    
  515.     SELECT clock_timestamp() INTO vNewTimestamp;
  516.     RAISE NOTICE 'Done update other_costs_usd for : %', vNewTimestamp - vOldTimestamp;
  517.     vOldTimestamp := vNewTimestamp;
  518.    
  519.     -- update line_of_business yang kosong menjadi DEFAULT
  520.     UPDATE tr_data_so_sales_commission_for_igs
  521.     SET line_of_business = vDefault
  522.     WHERE line_of_business IN (vEmptyString,vSpace);
  523.    
  524.     SELECT clock_timestamp() INTO vNewTimestamp;
  525.     RAISE NOTICE 'Done update line_of_business yang kosong menjadi DEFAULT for : %', vNewTimestamp - vOldTimestamp;
  526.     vOldTimestamp := vNewTimestamp;
  527.    
  528.     /* update bulan pelunasan */
  529.     UPDATE tr_data_so_sales_commission_for_igs B
  530.     SET date_year_month = A.date_year_month
  531.     FROM fi_temp_summary_monthly_ar A
  532.     WHERE A.balance_amount = A.payment_amount
  533.     AND B.invoice_id = A.invoice_id
  534.     AND B.doc_type_id = A.doc_type_id
  535.     AND B.session_id = pSessionId
  536.     --AND B.tenant_id = pTenantId
  537.     ;
  538.    
  539.     SELECT clock_timestamp() INTO vNewTimestamp;
  540.     RAISE NOTICE 'Done update bulan pelunasan for : %', vNewTimestamp - vOldTimestamp;
  541.     vOldTimestamp := vNewTimestamp;
  542.    
  543.     Open pRefHeader FOR
  544.     SELECT pOuId AS ou_id, f_get_ou_name(pOuId) AS ou_name, vDateFrom AS date_from, vDateTo AS date_to, pDatetime AS datetime, f_get_username(pUserId) AS username;
  545.     RETURN NEXT pRefHeader;
  546.    
  547.     SELECT clock_timestamp() INTO vNewTimestamp;
  548.     RAISE NOTICE 'Done pRefHeader for : %', vNewTimestamp - vOldTimestamp;
  549.     vOldTimestamp := vNewTimestamp;
  550.        
  551.     Open pRefDetail FOR
  552.     /*WITH vw_warranty_sell_amount AS (
  553.         SELECT A.invoice_id, B.do_item_id,  
  554.             CASE WHEN A.doc_type_id = vDocTypeReturnSalesInvoice
  555.                 THEN -1 * SUM(L.warranty_sell_amount)  
  556.             ELSE
  557.                 SUM(L.warranty_sell_amount)
  558.             END AS sum_warranty_sell_amount
  559.         FROM tr_data_so_sales_commission_for_igs A
  560.         INNER JOIN sl_do_item B ON B.do_item_id = A.do_item_id
  561.         INNER JOIN sl_invoice_item C ON C.ref_item_id = B.do_item_id
  562.         INNER JOIN sl_invoice D ON D.invoice_id = C.invoice_id
  563.         INNER JOIN sl_so_balance_warranty_invoice L ON L.ou_id = D.ou_id AND L.partner_id = D.partner_id
  564.             AND L.ref_doc_type_id = C.ref_doc_type_id AND L.ref_id = C.ref_id AND L.ref_item_id = C.ref_item_id
  565.             AND L.do_receipt_item_id = C.do_receipt_item_id
  566.         WHERE A.session_id = pSessionId
  567.         GROUP BY A.invoice_id, A.doc_type_id, B.do_item_id
  568.     )*/
  569.     SELECT A.line_of_business, f_get_partner_name(A.salesman_id) AS sales_name, f_get_partner_code(A.partner_id) AS partner_code, f_get_partner_name(A.partner_id) AS partner_name,
  570.         A.so_doc_date AS so_date, A.so_doc_no AS so_no, A.doc_type_id, A.inv_doc_date AS inv_date, A.inv_doc_no AS inv_no, f_get_brand_name(A.brand_id) as brand_name, f_get_product_code(A.product_id) AS product_code,
  571.         f_get_product_name(A.product_id) AS product_name, A.qty_dlv_int AS qty, A.inv_curr_code, (A.original_total_amount / A.qty_dlv_int) AS original_price,
  572.         A.denominator_rate/A.numerator_rate AS rate_to_usd, A.numerator_rate AS rate_to_idr, original_total_amount,
  573.         A.total_amount_usd, A.total_amount_idr, A.other_costs_curr_code, A.other_costs, A.other_costs_usd, A.other_costs_idr, A.date_year_month,
  574.         --A.warranty_sell_amount
  575.         COALESCE(C.sum_warranty_sell_amount, vNol)
  576.     FROM tr_data_so_sales_commission_for_igs A
  577.     LEFT OUTER JOIN sl_so_external_commission B ON A.so_id = B.so_id AND A.so_item_id = (SELECT MIN(K.so_item_id) FROM sl_so_item K WHERE K.so_id = B.so_id AND K.qty_so > 0)
  578.     LEFT JOIN tt_warranty_sell_amount C ON C.invoice_id = A.invoice_id AND C.do_item_id = A.do_item_id
  579.     WHERE A.session_id = pSessionId
  580.         AND A.qty_dlv_int <> 0
  581.     ORDER BY line_of_business, sales_name, partner_name, A.so_doc_no, A.doc_type_id, product_code;
  582.     RETURN NEXT pRefDetail;
  583.        
  584.     SELECT clock_timestamp() INTO vNewTimestamp;
  585.     RAISE NOTICE 'Done pRefDetail for : %', vNewTimestamp - vOldTimestamp;
  586.     vOldTimestamp := vNewTimestamp;
  587.  
  588.     DELETE FROM tr_data_so_sales_commission_for_igs WHERE session_id = pSessionId;
  589.     DELETE FROM tt_warranty_sell_amount WHERE session_id = pSessionId;
  590.    
  591.     SELECT clock_timestamp() INTO vNewTimestamp;
  592.     RAISE NOTICE 'Done delete tr_data_so_sales_commission_for_igs for : %', vNewTimestamp - vOldTimestamp;
  593.     vOldTimestamp := vNewTimestamp;
  594.    
  595.     RAISE NOTICE 'End at : %', clock_timestamp();
  596. END;
  597. $BODY$
  598.   LANGUAGE plpgsql VOLATILE
  599.   COST 100
  600.   ROWS 1000;
  601. /
Advertisement
Add Comment
Please, Sign In to add comment
Advertisement