Advertisement
tercnem

COSTING RM

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