Advertisement
aadddrr

pu_summary_purch

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