Advertisement
tercnem

Untitled

Sep 7th, 2020
1,293
0
Never
Not a member of Pastebin yet? Sign Up, it unlocks many cool features!
  1. CREATE OR REPLACE FUNCTION in_process_costing_wip(bigint, character varying, character varying, bigint, character varying, bigint)
  2.   RETURNS void AS
  3. $BODY$
  4. DECLARE
  5.  
  6.     pTenantId           ALIAS FOR $1;
  7.     pSessionId          ALIAS FOR $2;
  8.     pYearMonth          ALIAS FOR $3;
  9.     pOuId               ALIAS FOR $4;
  10.     pDatetime           ALIAS FOR $5;
  11.     pUserId             ALIAS FOR $6;
  12.  
  13.     vNextYearMonth          character varying(6);
  14.     vCurrGL                 character varying(5);
  15.     vFlagNo                 character varying(1);
  16.     vFlagYes                character varying(1);
  17.     vEmptyValue             character varying(1);
  18.     vEmptyId                bigint;
  19.     vDocTypeAwal            bigint;
  20.     vGroupProductFG         character varying(5);
  21.     vGroupProductRM         character varying(5);
  22.     vRoundingDigit          integer;
  23.     vTypeRate               character varying(5);
  24.     vStatusRelease          character varying(1);
  25.     vProductStatusPending   character varying := 'PENDING';
  26. BEGIN
  27.    
  28.     vFlagNo := 'N';
  29.     vFlagYes := 'Y';
  30.     vDocTypeAwal := -99;
  31.     vEmptyId := -99;
  32.     vEmptyValue := ' ';
  33.     vGroupProductFG := 'FG';
  34.     vGroupProductRM := 'RM';
  35.     vTypeRate := 'COM';
  36.     vStatusRelease := 'R';
  37.    
  38.     SELECT TO_CHAR(TO_DATE(MAX(pYearMonth),'YYYYMM') + interval '1 Month','YYYYMM') INTO vNextYearMonth;
  39.    
  40.     vCurrGL := f_get_value_system_config_by_param_code(pTenantId,'ValutaBuku');
  41.     vRoundingDigit := CAST(f_get_value_system_config_by_param_code(pTenantId,'rounding.gl.amount') AS integer);
  42.  
  43.     DELETE FROM tt_in_doc_product_price WHERE session_id = pSessionId;
  44.    
  45.     DELETE FROM tt_in_add_product_unamount WHERE session_id = pSessionId;
  46.    
  47.     DELETE FROM tt_in_product_base_price WHERE session_id = pSessionId;
  48.    
  49.     DELETE FROM tt_in_summary_monthly_product WHERE session_id = pSessionId;
  50.    
  51.     DELETE FROM tt_in_summary_monthly_cogs WHERE session_id = pSessionId;
  52.    
  53.     DELETE FROM tt_in_summary_monthly_amount_remain WHERE session_id = pSessionId;
  54.    
  55.     /*
  56.      * costing product hanya berdasarkan ou business unit ( artinya tbl cogs hanya ada ou_id )
  57.      */
  58.    
  59.     /*
  60.      * membuat summary nilai pembelian berdasarkan hasil jurnal
  61.      * untuk transaksi receive goods
  62.      * NK, 16 Feb 2015 : Pembelian Internal menghasilkan dokumen semua sesuai doc type Receive Goods
  63.      * Receive Goods : 111
  64.      *
  65.      * WTC, 20161123, Ambil data item dokumen Receive Goods beserta nilainya dari data jurnal, khusus untuk produk-produk yang not ready to sell
  66.      */
  67.     INSERT INTO in_summary_monthly_amount_wip
  68.     (date_year_month, tenant_id, ou_bu_id, ou_branch_id, ou_sub_bu_id,
  69.     doc_type_id, product_id, base_uom_id, qty,
  70.     gl_curr_code, gl_amount, flg_amount,
  71.     "version", create_datetime, create_user_id, update_datetime, update_user_id, remark)
  72.     SELECT pYearMonth, A.tenant_id, A.ou_bu_id, A.ou_branch_id, A.ou_sub_bu_id,
  73.         A.doc_type_id, C.product_id, C.uom_id, SUM(C.qty),
  74.         C.gl_curr_code, SUM(C.gl_amount), 'PURCH_PRICE',
  75.         0, pDatetime, pUserId, pDatetime, pUserId, vGroupProductFG
  76.     FROM gl_journal_trx A, dt_date B, gl_journal_trx_item C, m_document_journal D, vw_finish_goods_product E
  77.     WHERE A.tenant_id = pTenantId AND
  78.         A.ou_bu_id = pOuId AND
  79.         A.status_doc = vStatusRelease AND
  80.         A.doc_date = B.string_date AND
  81.         B.year_month_date = pYearMonth AND
  82.         A.journal_trx_id = C.journal_trx_id AND
  83.         A.doc_type_id = D.doc_type_id AND
  84.         D.ledger_code IN ('PURCH') AND
  85.         C.journal_desc = 'TEMPORARY_PRODUCT_STOCK' AND
  86.         A.doc_type_id IN (111) AND
  87.         C.product_id = E.product_id AND
  88.         f_check_product_ready_to_sell(C.product_id) = 0
  89.     GROUP BY A.tenant_id, A.ou_bu_id, A.ou_branch_id, A.ou_sub_bu_id, A.doc_type_id, C.product_id, C.uom_id, C.gl_curr_code;
  90.  
  91.     /*
  92.      * ambil data receive goods dari in_summary_monthly_amount_wip yang product finish goods
  93.      * NK, 16 Feb 2015 : receive goods internal menggunakan doc type receive goods
  94.      */        
  95.     INSERT INTO tt_in_doc_product_price
  96.     (session_id, tenant_id, ou_bu_id, ou_branch_id, ou_sub_bu_id, product_id,
  97.      doc_type_id, ref_id, doc_no, doc_date,
  98.      curr_code, amount, qty, uom_id,
  99.      numerator_rate, denominator_rate,
  100.      gl_curr_code, gl_amount)
  101.     SELECT pSessionId, A.tenant_id, A.ou_bu_id, A.ou_branch_id, A.ou_sub_bu_id, A.product_id,
  102.         A.doc_type_id, vEmptyId, vEmptyValue, vEmptyValue,
  103.         A.gl_curr_code, A.gl_amount, A.qty, A.base_uom_id,
  104.         1, 1,
  105.         A.gl_curr_code, A.gl_amount
  106.     FROM in_summary_monthly_amount_wip A, vw_finish_goods_product E
  107.     WHERE A.date_year_month = pYearMonth AND
  108.         A.doc_type_id IN (111) AND
  109.         A.tenant_id = pTenantId AND
  110.         A.ou_bu_id = pOuId AND
  111.         A.product_id = E.product_id;
  112.        
  113.     /*
  114.      * ambil data adjusment stok amount
  115.      * jika curr <> curr G/L, maka lakukan hitung rate untuk ke nilai sesuai valuta G/L
  116.      * 522 : adj stock amount ( mempengaruhi COGS )
  117.      * 523 : adj stock amount balance ( mempengaruhi saldo akhir )
  118.      * 528 : costing allocation to product ( mempengaruhi COGS )
  119.      *
  120.      * WTC, 20161126, ambil data adj stock amount balance dan costing allocation to product, khusus untuk produk not ready to sell.
  121.      * Ambil data adj stock amount, khusus untuk product not ready to sell yang product status nya PENDING. Nilainya menggunakan metode prorate
  122.      */
  123.     INSERT INTO tt_in_doc_product_price
  124.     (session_id, tenant_id, ou_bu_id, ou_branch_id, ou_sub_bu_id, product_id,
  125.      doc_type_id, ref_id, doc_no, doc_date,
  126.      curr_code, amount, qty, uom_id,
  127.      numerator_rate, denominator_rate,
  128.      gl_curr_code, gl_amount)
  129.     SELECT pSessionId, A.tenant_id, B.ou_bu_id, B.ou_branch_id, B.ou_sub_bu_id, A.product_id,
  130.         A.doc_type_id, A.ref_id, A.doc_no, A.doc_date,
  131.         A.curr_code, A.amount, A.qty, A.uom_id,
  132.         1, 1, vCurrGL, ROUND( A.amount, vRoundingDigit)
  133.     FROM in_product_price_balance A, m_ou_structure B, dt_date C, vw_finish_goods_product E
  134.     WHERE A.doc_date = C.string_date AND
  135.         C.year_month_date = pYearMonth AND
  136.         A.tenant_id = pTenantId AND
  137.         A.ou_id = B.ou_id AND
  138.         B.ou_bu_id = pOuId AND
  139.         A.doc_type_id IN (523, 528) AND
  140.         A.product_id = E.product_id AND
  141.         f_check_product_ready_to_sell(A.product_id) = 0;
  142.    
  143.     INSERT INTO tt_in_doc_product_price
  144.     (session_id, tenant_id, ou_bu_id, ou_branch_id, ou_sub_bu_id, product_id,
  145.      doc_type_id, ref_id, doc_no, doc_date,
  146.      curr_code, amount, qty, uom_id,
  147.      numerator_rate, denominator_rate,
  148.      gl_curr_code, gl_amount)
  149.     SELECT pSessionId, A.tenant_id, B.ou_bu_id, B.ou_branch_id, B.ou_sub_bu_id, A.product_id,
  150.         A.doc_type_id, A.ref_id, A.doc_no, A.doc_date,
  151.         A.curr_code, SUM(F.amount), SUM(F.qty_realization), A.uom_id,
  152.         1, 1, vCurrGL, ROUND(SUM(F.amount), vRoundingDigit)
  153.     FROM in_product_price_balance A, m_ou_structure B, dt_date C, vw_finish_goods_product E, in_inventory_item F
  154.     WHERE A.doc_date = C.string_date AND
  155.         C.year_month_date = pYearMonth AND
  156.         A.tenant_id = pTenantId AND
  157.         A.ou_id = B.ou_id AND
  158.         B.ou_bu_id = pOuId AND
  159.         A.doc_type_id = 522 AND
  160.         A.product_id = E.product_id AND
  161.         f_check_product_ready_to_sell(A.product_id) = 0 AND
  162.         A.ref_id = F.inventory_item_id AND
  163.         F.product_status = vProductStatusPending
  164.     GROUP BY A.tenant_id, B.ou_bu_id, B.ou_branch_id, B.ou_sub_bu_id, A.product_id,
  165.         A.doc_type_id, A.ref_id, A.doc_no, A.doc_date,
  166.         A.curr_code, A.uom_id;
  167.    
  168.     -- hitung nilai pembukuan untuk transaksi adjusment stok amount
  169.     UPDATE tt_in_doc_product_price SET numerator_rate = B.amount_to, denominator_rate = B.amount_from
  170.     FROM m_exchange_rate B
  171.     WHERE tt_in_doc_product_price.session_id = pSessionId AND
  172.         tt_in_doc_product_price.tenant_id = B.tenant_id AND
  173.         B.type_exchange_rate = vTypeRate AND
  174.         tt_in_doc_product_price.doc_date = B.date_from AND
  175.         tt_in_doc_product_price.curr_code = B.curr_code_from AND
  176.         tt_in_doc_product_price.gl_curr_code = B.curr_code_to AND
  177.         tt_in_doc_product_price.doc_type_id IN (522, 523, 528) AND
  178.         tt_in_doc_product_price.curr_code <> vCurrGL;
  179.  
  180.     UPDATE tt_in_doc_product_price SET gl_amount = ROUND(amount * numerator_rate / denominator_rate, vRoundingDigit)
  181.     WHERE tt_in_doc_product_price.session_id = pSessionId AND
  182.           tt_in_doc_product_price.doc_type_id IN (522, 523, 528) AND
  183.           tt_in_doc_product_price.curr_code <> vCurrGL;
  184.          
  185.     /*
  186.      * product non assembly
  187.      * ambil data transaksi yg tambah stok, tp belum memiliki nilai
  188.      * 1.adj stok qty plus : 521, khusus tuk product not ready to sell
  189.      */
  190.     INSERT INTO tt_in_add_product_unamount
  191.     (session_id, tenant_id, ou_bu_id, ou_branch_id, ou_sub_bu_id, product_id,
  192.      doc_type_id, qty, uom_id, gl_curr_code, gl_amount, flg_amount)
  193.     SELECT pSessionId, A.tenant_id, B.ou_bu_id, B.ou_branch_id, B.ou_sub_bu_id, A.product_id,
  194.         A.doc_type_id, A.qty, A.base_uom_id, vCurrGL, 0, vEmptyValue
  195.     FROM in_log_product_balance_stock A, m_ou_structure B, dt_date C, vw_finish_goods_product E
  196.     WHERE A.ou_id = B.ou_id AND
  197.         B.ou_bu_id = pOuId AND
  198.         A.doc_date = C.string_date AND
  199.         C.year_month_date = pYearMonth AND
  200.         A.doc_type_id = 521 AND
  201.         A.product_id = E.product_id AND
  202.         A.qty > 0 AND
  203.         f_check_product_ready_to_sell(A.product_id) = 0 AND
  204.         A.product_status = vProductStatusPending;
  205.  
  206.     /*
  207.      * buat data yang akan menjadi acuan harga standard
  208.      * 1.data purch price di bulan bersangkutan
  209.      * 2.data nilai barang di awal bulan
  210.      * 3.data master harga standard
  211.      */
  212.     INSERT INTO tt_in_product_base_price
  213.     (session_id, tenant_id, ou_id, product_id,
  214.      flg_amount, qty, uom_id, gl_curr_code, gl_amount)
  215.     SELECT A.session_id, A.tenant_id, A.ou_bu_id, A.product_id,
  216.         'PURCH_PRICE', SUM(A.qty), A.uom_id, A.gl_curr_code, SUM(A.gl_amount)
  217.     FROM tt_in_doc_product_price A
  218.     WHERE A.session_id = pSessionId AND
  219.         A.doc_type_id IN (111)
  220.     GROUP BY A.session_id, A.tenant_id, A.ou_bu_id, A.product_id,
  221.         A.uom_id, A.gl_curr_code;
  222.    
  223.     INSERT INTO tt_in_product_base_price
  224.     (session_id, tenant_id, ou_id, product_id,
  225.      flg_amount, qty, uom_id, gl_curr_code, gl_amount)
  226.     SELECT pSessionId, A.tenant_id, A.ou_bu_id, A.product_id,
  227.         'BGN_BALANCE', SUM(A.qty), A.base_uom_id, A.gl_curr_code, SUM(A.gl_amount)
  228.     FROM in_summary_monthly_amount_wip A, vw_finish_goods_product E
  229.     WHERE A.date_year_month = pYearMonth AND
  230.         A.doc_type_id = vDocTypeAwal AND
  231.         A.tenant_id = pTenantId AND
  232.         A.ou_bu_id = pOuId AND
  233.         A.product_id = E.product_id
  234.     GROUP BY A.tenant_id, A.ou_bu_id, A.product_id,
  235.         A.base_uom_id, A.gl_curr_code;
  236.    
  237.     INSERT INTO tt_in_product_base_price
  238.     (session_id, tenant_id, ou_id, product_id,
  239.      flg_amount, qty, uom_id, gl_curr_code, gl_amount)
  240.     SELECT pSessionId, A.tenant_id, A.ou_id, A.product_id,
  241.         'STANDARD_PRICE', 0, E.base_uom_id, A.curr_code, SUM(A.amount)
  242.     FROM in_product_standard_cogs A, vw_finish_goods_product E
  243.     WHERE A.tenant_id = pTenantId AND
  244.         A.ou_id = pOuId AND
  245.         A.year_month_date = pYearMonth AND
  246.         A.product_id = E.product_id
  247.     GROUP BY A.tenant_id, A.ou_id, A.product_id, A.curr_code, E.base_uom_id;
  248.    
  249.     /*
  250.      * isi nilai data tt_in_add_product_unamount dengan urutan :
  251.      * 1. update dengan data flg amount STANDARD_PRICE
  252.      * 2. jika belum ada, update dengan data flg amount BGN_BALANCE
  253.      * 3. jika belum ada, update dengan data flg amount PURCH_PRICE
  254.      */
  255.    
  256.     UPDATE tt_in_add_product_unamount SET gl_amount = tt_in_add_product_unamount.qty * A.gl_amount, flg_amount = A.flg_amount
  257.     FROM tt_in_product_base_price A
  258.     WHERE A.session_id = pSessionId AND
  259.         tt_in_add_product_unamount.session_id = A.session_id AND
  260.         tt_in_add_product_unamount.tenant_id = A.tenant_id AND
  261.         tt_in_add_product_unamount.ou_bu_id = A.ou_id AND
  262.         tt_in_add_product_unamount.product_id = A.product_id AND
  263.         tt_in_add_product_unamount.flg_amount = vEmptyValue AND
  264.         A.flg_amount = 'STANDARD_PRICE';
  265.    
  266.     UPDATE tt_in_add_product_unamount SET gl_amount = ROUND(tt_in_add_product_unamount.qty * ( A.gl_amount / A.qty ), vRoundingDigit), flg_amount = A.flg_amount
  267.     FROM tt_in_product_base_price A
  268.     WHERE A.session_id = pSessionId AND
  269.         tt_in_add_product_unamount.session_id = A.session_id AND
  270.         tt_in_add_product_unamount.tenant_id = A.tenant_id AND
  271.         tt_in_add_product_unamount.ou_bu_id = A.ou_id AND
  272.         tt_in_add_product_unamount.product_id = A.product_id AND
  273.         tt_in_add_product_unamount.flg_amount = vEmptyValue AND    
  274.         A.flg_amount = 'BGN_BALANCE' AND
  275.         A.qty <> 0;
  276.        
  277.     UPDATE tt_in_add_product_unamount SET gl_amount = ROUND(tt_in_add_product_unamount.qty * ( A.gl_amount / A.qty ), vRoundingDigit), flg_amount = A.flg_amount
  278.     FROM tt_in_product_base_price A
  279.     WHERE A.session_id = pSessionId AND
  280.         tt_in_add_product_unamount.session_id = A.session_id AND
  281.         tt_in_add_product_unamount.tenant_id = A.tenant_id AND
  282.         tt_in_add_product_unamount.ou_bu_id = A.ou_id AND
  283.         tt_in_add_product_unamount.product_id = A.product_id AND
  284.         tt_in_add_product_unamount.flg_amount = vEmptyValue AND    
  285.         A.flg_amount = 'PURCH_PRICE' AND
  286.         A.qty <> 0;
  287.  
  288.        
  289. /*
  290.  *  menghitung harga rata rata product (non assembly ) berdasarkan :
  291.  *  1. harga purchasing
  292.  *  2. harga adj stock amount ( bukan yg balance amount )
  293.  *  3. transaksi tambah stok qty, dengan harga sudah diproses : retur jual, adj stok qty > 0
  294.  *  4. harga saldo awal
  295.  */    
  296.     INSERT INTO tt_in_summary_monthly_product
  297.     (session_id, date_year_month, tenant_id, ou_bu_id, ou_branch_id, ou_sub_bu_id,
  298.     doc_type_id, product_id, base_uom_id, qty,
  299.     gl_curr_code, gl_amount, flg_amount)
  300.     SELECT pSessionId, pYearMonth, A.tenant_id, A.ou_bu_id, A.ou_branch_id, A.ou_sub_bu_id,
  301.         A.doc_type_id, A.product_id, A.uom_id, SUM(A.qty),
  302.         A.gl_curr_code, SUM(A.gl_amount), 'PURCH_PRICE'
  303.     FROM tt_in_doc_product_price A
  304.     WHERE A.session_id = pSessionId AND
  305.         A.doc_type_id IN (111)
  306.     GROUP BY A.tenant_id, A.ou_bu_id, A.ou_branch_id, A.ou_sub_bu_id, A.doc_type_id, A.product_id, A.uom_id, A.gl_curr_code;
  307.    
  308.     INSERT INTO tt_in_summary_monthly_product
  309.     (session_id, date_year_month, tenant_id, ou_bu_id, ou_branch_id, ou_sub_bu_id,
  310.     doc_type_id, product_id, base_uom_id, qty,
  311.     gl_curr_code, gl_amount, flg_amount)
  312.     SELECT pSessionId, pYearMonth, A.tenant_id, A.ou_bu_id, A.ou_branch_id, A.ou_sub_bu_id,
  313.         A.doc_type_id, A.product_id, A.uom_id, SUM(A.qty),
  314.         A.gl_curr_code, SUM(A.gl_amount), 'TRANSACTION'
  315.     FROM tt_in_doc_product_price A
  316.     WHERE A.session_id = pSessionId AND
  317.         A.doc_type_id IN ( 522, 528 )
  318.     GROUP BY A.tenant_id, A.ou_bu_id, A.ou_branch_id, A.ou_sub_bu_id, A.doc_type_id, A.product_id, A.uom_id, A.gl_curr_code;
  319.  
  320.     INSERT INTO tt_in_summary_monthly_product
  321.     (session_id, date_year_month, tenant_id, ou_bu_id, ou_branch_id, ou_sub_bu_id,
  322.     doc_type_id, product_id, base_uom_id, qty,
  323.     gl_curr_code, gl_amount, flg_amount)
  324.     SELECT pSessionId, pYearMonth, A.tenant_id, A.ou_bu_id, A.ou_branch_id, A.ou_sub_bu_id,
  325.         A.doc_type_id, A.product_id, A.uom_id, SUM(A.qty),
  326.         A.gl_curr_code, SUM(A.gl_amount), A.flg_amount
  327.     FROM tt_in_add_product_unamount A
  328.     WHERE A.session_id = pSessionId
  329.     GROUP BY A.tenant_id, A.ou_bu_id, A.ou_branch_id, A.ou_sub_bu_id, A.doc_type_id, A.product_id, A.uom_id, A.gl_curr_code, A.flg_amount;
  330.  
  331.     INSERT INTO tt_in_summary_monthly_product
  332.     (session_id, date_year_month, tenant_id, ou_bu_id, ou_branch_id, ou_sub_bu_id,
  333.     doc_type_id, product_id, base_uom_id, qty,
  334.     gl_curr_code, gl_amount, flg_amount)
  335.     SELECT pSessionId, pYearMonth, A.tenant_id, A.ou_bu_id, A.ou_branch_id, A.ou_sub_bu_id,
  336.         A.doc_type_id, A.product_id, A.base_uom_id, SUM(A.qty),
  337.         A.gl_curr_code, SUM(A.gl_amount), A.flg_amount
  338.     FROM in_summary_monthly_amount_wip A, vw_finish_goods_product E
  339.     WHERE A.date_year_month = pYearMonth AND
  340.         A.doc_type_id = vDocTypeAwal AND
  341.         A.ou_bu_id = pOuId AND
  342.         A.tenant_id = pTenantId AND
  343.         A.product_id = E.product_id
  344.     GROUP BY A.tenant_id, A.ou_bu_id, A.ou_branch_id, A.ou_sub_bu_id, A.doc_type_id, A.product_id, A.base_uom_id, A.gl_curr_code, A.flg_amount;
  345.  
  346.     /*
  347.      * hitung harga rata-rata sebagai dasar harga pokok
  348.      */
  349.     INSERT INTO tt_in_summary_monthly_cogs
  350.     (session_id, date_year_month, tenant_id, ou_id,
  351.     product_id, qty_total, curr_code, amount_total, avg_price)
  352.     SELECT pSessionId, pYearMonth, A.tenant_id, A.ou_bu_id,
  353.         A.product_id, SUM(A.qty), A.gl_curr_code, SUM(A.gl_amount), 0
  354.     FROM tt_in_summary_monthly_product A
  355.     WHERE A.session_id = pSessionId
  356.     GROUP BY A.tenant_id, A.ou_bu_id, A.product_id, A.gl_curr_code;
  357.    
  358.     UPDATE tt_in_summary_monthly_cogs
  359.       SET avg_price = amount_total / qty_total
  360.     WHERE session_id = pSessionId AND
  361.       qty_total <> 0;
  362.    
  363.     /*
  364.      * memberikan nilai untuk transaksi stok yang mengurangi qty, sesuai harga rata rata bulan ini
  365.      * - transaksi adj stok qty(521), yang qty < 0, produknya not ready to sell, dan product status nya PENDING.
  366.      * - transaksi LPBD (198), yg  product statusnya PENDING
  367.      */
  368.     INSERT INTO tt_in_summary_monthly_product
  369.     (session_id, date_year_month, tenant_id,  ou_bu_id, ou_branch_id, ou_sub_bu_id,
  370.     doc_type_id, product_id, base_uom_id, qty,
  371.     gl_curr_code, gl_amount, flg_amount)
  372.     SELECT pSessionId, pYearMonth, A.tenant_id, B.ou_bu_id, B.ou_branch_id, B.ou_sub_bu_id,
  373.         A.doc_type_id, A.product_id, A.base_uom_id, SUM(A.qty),
  374.         vCurrGL, 0, 'MONTHLY_AVG'
  375.     FROM in_log_product_balance_stock A, m_ou_structure B, dt_date C, vw_finish_goods_product E
  376.     WHERE A.ou_id = B.ou_id AND
  377.         B.ou_bu_id = pOuId AND
  378.         A.doc_date = C.string_date AND
  379.         C.year_month_date = pYearMonth AND
  380.         A.doc_type_id = 198 AND
  381.         A.product_id = E.product_id AND
  382.         A.product_status = vProductStatusPending
  383.     GROUP BY A.tenant_id, B.ou_bu_id, B.ou_branch_id, B.ou_sub_bu_id, A.doc_type_id, A.product_id, A.base_uom_id;  
  384.  
  385.     INSERT INTO tt_in_summary_monthly_product
  386.     (session_id, date_year_month, tenant_id,  ou_bu_id, ou_branch_id, ou_sub_bu_id,
  387.     doc_type_id, product_id, base_uom_id, qty,
  388.     gl_curr_code, gl_amount, flg_amount)
  389.     SELECT pSessionId, pYearMonth, A.tenant_id, B.ou_bu_id, B.ou_branch_id, B.ou_sub_bu_id,
  390.         A.doc_type_id, A.product_id, A.base_uom_id, SUM(A.qty),
  391.         vCurrGL, 0, 'MONTHLY_AVG'
  392.     FROM in_log_product_balance_stock A, m_ou_structure B, dt_date C, vw_finish_goods_product E
  393.     WHERE A.ou_id = B.ou_id AND
  394.         B.ou_bu_id = pOuId AND
  395.         A.doc_date = C.string_date AND
  396.         C.year_month_date = pYearMonth AND
  397.         A.doc_type_id = 521 AND
  398.         A.product_id = E.product_id AND
  399.         A.qty < 0 AND
  400.         f_check_product_ready_to_sell(A.product_id) = 0 AND
  401.         A.product_status = vProductStatusPending
  402.     GROUP BY A.tenant_id, B.ou_bu_id, B.ou_branch_id, B.ou_sub_bu_id, A.doc_type_id, A.product_id, A.base_uom_id;
  403.  
  404.     UPDATE tt_in_summary_monthly_product SET gl_amount = ROUND(qty * (A.amount_total / A.qty_total), vRoundingDigit)
  405.     FROM tt_in_summary_monthly_cogs A
  406.     WHERE A.session_id = pSessionId AND
  407.         tt_in_summary_monthly_product.session_id = A.session_id AND
  408.         tt_in_summary_monthly_product.tenant_id = A.tenant_id AND
  409.         tt_in_summary_monthly_product.ou_bu_id = A.ou_id AND
  410.         tt_in_summary_monthly_product.product_id = A.product_id AND
  411.         tt_in_summary_monthly_product.doc_type_id IN (198,521) AND
  412.         tt_in_summary_monthly_product.flg_amount = 'MONTHLY_AVG' AND
  413.         A.qty_total <> 0;
  414.  
  415.     /*
  416.      * untuk menghitung saldo akhir di bulan tersebut, dengan cara membuat record saldo awal untuk bulan berikutnya
  417.      * 1. ambil data adj stok balance amount ( adjust nilai akhir saldo barang )
  418.      * 2. hitung saldo akhir
  419.      */    
  420.     INSERT INTO tt_in_summary_monthly_product
  421.     (session_id, date_year_month, tenant_id, ou_bu_id, ou_branch_id, ou_sub_bu_id,
  422.     doc_type_id, product_id, base_uom_id, qty,
  423.     gl_curr_code, gl_amount, flg_amount)
  424.     SELECT pSessionId, pYearMonth, A.tenant_id, A.ou_bu_id, A.ou_branch_id, A.ou_sub_bu_id,
  425.         A.doc_type_id, A.product_id, A.uom_id, SUM(A.qty),
  426.         A.gl_curr_code, SUM(A.gl_amount), 'TRANSACTION'
  427.     FROM tt_in_doc_product_price A
  428.     WHERE A.session_id = pSessionId AND
  429.         A.doc_type_id = 523
  430.     GROUP BY A.tenant_id, A.ou_bu_id, A.ou_branch_id, A.ou_sub_bu_id, A.doc_type_id, A.product_id, A.uom_id, A.gl_curr_code;
  431.        
  432.     /*
  433.      * Persiapan data saldo awal untuk bulan berikutnya. Periksa terlebih dahulu apakah ada data yg qty = 0, tetapi gl_amount <> 0.
  434.      * Nilai gl_amount tsb akan dialokasikan ke data transaksi pengeluaran stok dengan id terbesar untuk product ybs.
  435.      */
  436.     INSERT INTO tt_in_summary_monthly_amount_remain
  437.     (session_id, date_year_month, tenant_id, ou_bu_id, ou_branch_id, ou_sub_bu_id,
  438.     doc_type_id, product_id, base_uom_id, qty,
  439.     gl_curr_code, gl_amount, flg_amount, summary_monthly_product_id)
  440.     SELECT pSessionId, A.date_year_month, A.tenant_id, A.ou_bu_id, vEmptyId, vEmptyId,
  441.         vDocTypeAwal, A.product_id, A.base_uom_id, SUM(A.qty),
  442.         vCurrGL, SUM(A.gl_amount), 'BGN_BALANCE', vEmptyId
  443.     FROM tt_in_summary_monthly_product A
  444.     WHERE A.session_id = pSessionId
  445.     GROUP BY A.date_year_month, A.tenant_id, A.ou_bu_id, A.product_id, A.base_uom_id;
  446.    
  447.     -- Cari id data sebagai penampung alokasi nilai
  448.     UPDATE tt_in_summary_monthly_amount_remain
  449.         SET summary_monthly_product_id = (
  450.             SELECT MAX(A.summary_monthly_product_id)
  451.             FROM tt_in_summary_monthly_product A
  452.             WHERE A.session_id = pSessionId AND
  453.                 tt_in_summary_monthly_amount_remain.session_id = A.session_id AND
  454.                 tt_in_summary_monthly_amount_remain.date_year_month = A.date_year_month AND
  455.                 tt_in_summary_monthly_amount_remain.tenant_id = A.tenant_id AND
  456.                 tt_in_summary_monthly_amount_remain.ou_bu_id = A.ou_bu_id AND
  457.                 tt_in_summary_monthly_amount_remain.product_id = A.product_id AND
  458.                 A.doc_type_id IN (511,311,431,526,521,413) AND
  459.                 A.flg_amount = 'MONTHLY_AVG')
  460.     WHERE session_id = pSessionId AND qty = 0 AND gl_amount <> 0;
  461.    
  462.     /*
  463.      * NK, 16 Feb 2015
  464.      * simpan terlebih dahulu data product yang qty = 0, dan nilai <> 0
  465.      * dimana nilai dari product tersebut akan dialokasi ke trx yang menggunakan produk tersebut
  466.      */
  467.     INSERT INTO in_summary_monthly_zero_qty_amount_wip
  468.     (date_year_month, tenant_id, ou_bu_id, ou_branch_id, ou_sub_bu_id,
  469.     product_id, qty_sum, base_uom_id, gl_curr_code, amount_sum,
  470.     doc_type_id, qty, gl_amount, remark)
  471.     SELECT A.date_year_month, A.tenant_id, A.ou_bu_id, A.ou_branch_id, A.ou_sub_bu_id,
  472.         A.product_id, A.qty, A.base_uom_id, A.gl_curr_code, A.gl_amount,
  473.         B.doc_type_id, B.qty, B.gl_amount, vGroupProductFG
  474.     FROM tt_in_summary_monthly_amount_remain A, tt_in_summary_monthly_product B
  475.     WHERE A.session_id = pSessionId AND
  476.         A.summary_monthly_product_id <> vEmptyId AND
  477.         B.summary_monthly_product_id = A.summary_monthly_product_id;
  478.                
  479.     UPDATE tt_in_summary_monthly_product SET gl_amount = tt_in_summary_monthly_product.gl_amount - A.gl_amount
  480.     FROM tt_in_summary_monthly_amount_remain A
  481.     WHERE A.session_id = pSessionId AND
  482.         A.summary_monthly_product_id <> vEmptyId AND
  483.         tt_in_summary_monthly_product.summary_monthly_product_id = A.summary_monthly_product_id;
  484.        
  485.     INSERT INTO tt_in_summary_monthly_product
  486.     (session_id, date_year_month, tenant_id, ou_bu_id, ou_branch_id, ou_sub_bu_id,
  487.     doc_type_id, product_id, base_uom_id, qty, gl_curr_code, gl_amount, flg_amount)
  488.     SELECT A.session_id, vNextYearMonth, A.tenant_id, A.ou_bu_id, A.ou_branch_id, A.ou_sub_bu_id,
  489.         A.doc_type_id, A.product_id, A.base_uom_id, A.qty, A.gl_curr_code, A.gl_amount, A.flg_amount
  490.     FROM tt_in_summary_monthly_amount_remain A
  491.     WHERE A.session_id = pSessionId AND A.qty <> 0;
  492.                
  493.     INSERT INTO in_summary_monthly_cogs_wip
  494.     (date_year_month, tenant_id, ou_id, product_id,
  495.     qty_total, curr_code, amount_total, avg_price,
  496.     "version", create_datetime, create_user_id, update_datetime, update_user_id, remark)
  497.     SELECT A.date_year_month, A.tenant_id, A.ou_id, A.product_id,
  498.             A.qty_total, A.curr_code, A.amount_total, A.avg_price,
  499.             0, pDatetime, pUserId, pDatetime, pUserId, vGroupProductFG
  500.     FROM tt_in_summary_monthly_cogs A
  501.     WHERE A.session_id = pSessionId;
  502.        
  503.     INSERT INTO in_summary_monthly_amount_wip
  504.     (date_year_month, tenant_id, ou_bu_id, ou_branch_id, ou_sub_bu_id,
  505.     doc_type_id, product_id, base_uom_id, qty,
  506.     gl_curr_code, gl_amount, flg_amount,
  507.     "version", create_datetime, create_user_id, update_datetime, update_user_id, remark)
  508.     SELECT A.date_year_month, A.tenant_id, A.ou_bu_id, A.ou_branch_id, A.ou_sub_bu_id,
  509.         A.doc_type_id, A.product_id, A.base_uom_id, A.qty,
  510.         A.gl_curr_code, A.gl_amount, A.flg_amount,
  511.         0, pDatetime, pUserId, pDatetime, pUserId, vGroupProductFG
  512.     FROM tt_in_summary_monthly_product A
  513.     WHERE A.session_id = pSessionId AND
  514.             A.date_year_month = pYearMonth AND
  515.             A.doc_type_id NOT IN (vDocTypeAwal, 111);
  516.  
  517.     INSERT INTO in_summary_monthly_amount_wip
  518.     (date_year_month, tenant_id, ou_bu_id, ou_branch_id, ou_sub_bu_id,
  519.     doc_type_id, product_id, base_uom_id, qty,
  520.     gl_curr_code, gl_amount, flg_amount,
  521.     "version", create_datetime, create_user_id, update_datetime, update_user_id, remark)
  522.     SELECT A.date_year_month, A.tenant_id, A.ou_bu_id, A.ou_branch_id, A.ou_sub_bu_id,
  523.         A.doc_type_id, A.product_id, A.base_uom_id, A.qty,
  524.         A.gl_curr_code, A.gl_amount, A.flg_amount,
  525.         0, pDatetime, pUserId, pDatetime, pUserId, vGroupProductFG
  526.     FROM tt_in_summary_monthly_product A
  527.     WHERE A.session_id = pSessionId AND
  528.         A.date_year_month = vNextYearMonth;
  529.        
  530.     DELETE FROM tt_in_doc_product_price WHERE session_id = pSessionId;
  531.    
  532.     DELETE FROM tt_in_add_product_unamount WHERE session_id = pSessionId;
  533.    
  534.     DELETE FROM tt_in_product_base_price WHERE session_id = pSessionId;
  535.    
  536.     DELETE FROM tt_in_summary_monthly_product WHERE session_id = pSessionId;
  537.    
  538.     DELETE FROM tt_in_summary_monthly_cogs WHERE session_id = pSessionId;
  539.    
  540.     DELETE FROM tt_in_summary_monthly_amount_remain WHERE session_id = pSessionId;
  541.    
  542.  END;
  543. $BODY$
  544.   LANGUAGE plpgsql VOLATILE
  545.   COST 100;
  546.   /
Advertisement
Add Comment
Please, Sign In to add comment
Advertisement