Advertisement
aadddrr

pu_summary_purch_20170809

Aug 8th, 2017
70
0
Never
Not a member of Pastebin yet? Sign Up, it unlocks many cool features!
  1. --Modified by Adrian, Jul 31, 2017, mengubah order pada summary_monthly_purchasing_temp menjadi ORDER BY C.ref_doc_date DESC, C.create_datetime DESC
  2. --meng-comment kondisi AND A.item_amount > 0
  3. --po_balance_invoice_id diambil per tanggal dan hanya yang terakhir
  4.  
  5. CREATE OR REPLACE FUNCTION pu_summary_purch(bigint, character varying, bigint, character varying, character varying, bigint)
  6.   RETURNS void AS
  7. $BODY$
  8. DECLARE
  9.     pTenantId           ALIAS FOR $1;
  10.     pSessionId          ALIAS FOR $2;
  11.     pOuId               ALIAS FOR $3;
  12.     pYearMonth          ALIAS FOR $4;
  13.     pDatetime           ALIAS FOR $5;
  14.     pUserId             ALIAS FOR $6;
  15.  
  16.     vReceiveGoodsDocTypeId  bigint;
  17.     vPrevYearMonth      character varying(6);
  18.     vDefaultCurrCode    character varying(10);
  19.     vDefaultPrice       numeric;
  20.     vDefaultGlCurrCode  character varying(100);
  21.     vRoundingMode       character varying(10);
  22. BEGIN
  23.    
  24.     vReceiveGoodsDocTypeId := 111;
  25.     vDefaultCurrCode := '-99';
  26.     vDefaultPrice := 0;
  27.    
  28.     vDefaultGlCurrCode := f_get_value_system_config_by_param_code(pTenantId,'ValutaBuku');
  29.     vRoundingMode := f_get_value_system_config_by_param_code(pTenantId, 'rounding.mode.non.tax');
  30.    
  31.     SELECT TO_CHAR(TO_DATE(pYearMonth,'YYYYMM') - interval '1 Month','YYYYMM') INTO vPrevYearMonth;
  32.    
  33.     INSERT INTO pu_summary_monthly_latest_purchasing
  34.         (tenant_id, ou_id, year_month_date,
  35.          product_id, curr_code, nett_price, gross_price,
  36.          gl_curr_code, gl_nett_price, gl_gross_price,
  37.          ref_doc_type_id, ref_id, ref_doc_no, ref_doc_date,
  38.          version, create_datetime, create_user_id, update_datetime, update_user_id)
  39.     SELECT tenant_id, ou_id, pYearMonth,
  40.            product_id, curr_code, nett_price, gross_price,
  41.            gl_curr_code, gl_nett_price, gl_gross_price,
  42.            ref_doc_type_id, ref_id, ref_doc_no, ref_doc_date,
  43.            0, pDatetime, pUserId, pDatetime, pUserId
  44.     FROM pu_summary_monthly_latest_purchasing
  45.     WHERE ou_id = pOuId
  46.     AND tenant_id = pTenantId
  47.     AND year_month_date = vPrevYearMonth;
  48.    
  49.     INSERT INTO pu_summary_monthly_latest_purchasing
  50.         (tenant_id, ou_id, year_month_date,
  51.          product_id, curr_code, nett_price, gross_price,
  52.          gl_curr_code, gl_nett_price, gl_gross_price,
  53.          ref_doc_type_id, ref_id, ref_doc_no, ref_doc_date,
  54.          version, create_datetime, create_user_id, update_datetime, update_user_id)
  55.     SELECT A.tenant_id, pOuId, pYearMonth,
  56.            A.product_id, vDefaultCurrCode, vDefaultPrice, vDefaultPrice,
  57.            vDefaultGlCurrCode, vDefaultPrice, vDefaultPrice,
  58.            -99, -99, ' ', ' ',
  59.            0, pDatetime, pUserId, pDatetime, pUserId
  60.     FROM m_product A
  61.     WHERE A.tenant_id = pTenantId
  62.     AND NOT EXISTS (
  63.         SELECT 1 FROM pu_summary_monthly_latest_purchasing B
  64.         WHERE B.ou_id = pOuId
  65.         AND B.tenant_id = pTenantId
  66.         AND B.year_month_date = pYearMonth
  67.         AND B.product_id = A.product_id
  68.     )
  69.     AND NOT EXISTS (
  70.         SELECT 1 FROM m_ext_product C
  71.         WHERE C.product_id = A.product_id
  72.     );
  73.    
  74.     WITH summary_monthly_purchasing_temp AS (
  75.         SELECT A.tenant_id, A.ou_id, F.year_month_date,
  76.            B.product_id, A.curr_code AS curr_code,
  77.            CASE WHEN vRoundingMode = 'RD'
  78.             THEN TRUNC(SUM(A.item_amount) / SUM(A.qty_rcv_po), f_get_digit_decimal_doc_curr(-99, A.curr_code))
  79.             ELSE ROUND(SUM(A.item_amount) / SUM(A.qty_rcv_po), f_get_digit_decimal_doc_curr(-99, A.curr_code))
  80.            END AS nett_price,
  81.            CASE WHEN vRoundingMode = 'RD'
  82.             THEN TRUNC(SUM(A.item_amount + COALESCE(G.tax_amount, 0)) / SUM(A.qty_rcv_po), f_get_digit_decimal_doc_curr(-99, A.curr_code))
  83.             ELSE ROUND(SUM(A.item_amount + COALESCE(G.tax_amount, 0)) / SUM(A.qty_rcv_po), f_get_digit_decimal_doc_curr(-99, A.curr_code))
  84.            END AS gross_price,
  85.            CASE WHEN vRoundingMode = 'RD'
  86.             THEN TRUNC(SUM(A.item_amount) / SUM(A.qty_rcv_po), f_get_digit_decimal_doc_curr(-99, vDefaultGlCurrCode)) * f_commercial_rate(pTenantId, A.ref_doc_date, A.curr_code, vDefaultGlCurrCode)
  87.             ELSE ROUND(SUM(A.item_amount) / SUM(A.qty_rcv_po), f_get_digit_decimal_doc_curr(-99, vDefaultGlCurrCode)) * f_commercial_rate(pTenantId, A.ref_doc_date, A.curr_code, vDefaultGlCurrCode)
  88.            END AS gl_nett_price,
  89.            CASE WHEN vRoundingMode = 'RD'
  90.             THEN TRUNC(SUM(A.item_amount + COALESCE(G.tax_amount, 0)) / SUM(A.qty_rcv_po), f_get_digit_decimal_doc_curr(-99, vDefaultGlCurrCode)) * f_commercial_rate(pTenantId, A.ref_doc_date, A.curr_code, vDefaultGlCurrCode)
  91.             ELSE ROUND(SUM(A.item_amount + COALESCE(G.tax_amount, 0)) / SUM(A.qty_rcv_po), f_get_digit_decimal_doc_curr(-99, vDefaultGlCurrCode)) * f_commercial_rate(pTenantId, A.ref_doc_date, A.curr_code, vDefaultGlCurrCode)
  92.             END AS gl_gross_price,
  93.            A.ref_doc_type_id, A.ref_id, A.ref_doc_no, A.ref_doc_date
  94.         FROM pu_po_balance_invoice A
  95.         INNER JOIN pu_receive_goods_item B ON A.ref_item_id = B.receive_goods_item_id
  96.         INNER JOIN dt_date F ON A.ref_doc_date = F.string_date
  97.         LEFT OUTER JOIN pu_po_balance_invoice_tax G
  98.             ON A.tenant_id = G.tenant_id
  99.             AND A.ou_id = G.ou_id
  100.             AND A.partner_id = G.partner_id
  101.             AND A.ref_doc_type_id = G.ref_doc_type_id
  102.             AND A.ref_id = G.ref_id
  103.             AND A.ref_item_id = G.ref_item_id
  104.         WHERE A.ref_doc_type_id = vReceiveGoodsDocTypeId
  105.         --AND A.item_amount > 0
  106.         AND F.year_month_date = pYearMonth
  107.         AND A.ou_id = pOuId
  108.         AND A.tenant_id = pTenantId
  109.         AND A.po_balance_invoice_id = (
  110.             SELECT C.po_balance_invoice_id
  111.             FROM pu_po_balance_invoice C
  112.             INNER JOIN pu_receive_goods_item D ON C.ref_item_id = D.receive_goods_item_id
  113.             INNER JOIN dt_date E ON C.ref_doc_date = E.string_date
  114.             WHERE D.product_id = B.product_id
  115.             --AND E.year_month_date = F.year_month_date
  116.             AND C.ref_doc_date <= A.ref_doc_date
  117.             AND C.ou_id = A.ou_id
  118.             AND C.ref_doc_type_id = vReceiveGoodsDocTypeId
  119.             AND C.tenant_id = pTenantId
  120.             ORDER BY C.ref_doc_date DESC, C.create_datetime DESC, D.line_no DESC
  121.             LIMIT 1
  122.         )
  123.         GROUP BY A.tenant_id, A.ou_id, F.year_month_date, B.product_id, A.curr_code, A.ref_doc_type_id, A.ref_id, A.ref_doc_no, A.ref_doc_date
  124.     )
  125.     UPDATE pu_summary_monthly_latest_purchasing Z
  126.     SET curr_code = Y.curr_code, nett_price = Y.nett_price, gross_price = Y.gross_price,
  127.         gl_curr_code = vDefaultGlCurrCode, gl_nett_price = Y.gl_nett_price, gl_gross_price = Y.gl_gross_price,
  128.         ref_doc_type_id = Y.ref_doc_type_id, ref_id = Y.ref_id, ref_doc_no = Y.ref_doc_no, ref_doc_date = Y.ref_doc_date,
  129.         version = Z.version + 1, update_datetime = pDatetime, update_user_id = pUserId
  130.     FROM summary_monthly_purchasing_temp Y
  131.     WHERE Y.tenant_id = Z.tenant_id
  132.     AND Y.year_month_date = Z.year_month_date
  133.     AND Y.product_id = Z.product_id
  134.     AND Y.ou_id = Z.ou_id;
  135.    
  136.     DELETE FROM pu_summary_monthly_latest_purchasing A
  137.     WHERE A.tenant_id = pTenantId
  138.     AND A.year_month_date = pYearMonth
  139.     AND A.ou_id = pOuId
  140.     AND A.curr_code = vDefaultCurrCode;
  141.    
  142. END;
  143. $BODY$
  144.   LANGUAGE plpgsql VOLATILE
  145.   COST 100;
  146.   /
Advertisement
Add Comment
Please, Sign In to add comment
Advertisement