Advertisement
tko_pb

m_production_run 10 september

Sep 9th, 2018
428
0
Never
Not a member of Pastebin yet? Sign Up, it unlocks many cool features!
  1. CREATE OR REPLACE FUNCTION public.m_production_run(pinstance_id character varying)
  2.  RETURNS void
  3.  LANGUAGE plpgsql
  4.  SET search_path TO '$user', 'public'
  5. AS $function$ DECLARE
  6. /*************************************************************************
  7.   * The contents of this file are subject to the Compiere Public
  8.   * License 1.1 ("License"); You may not use this file except in
  9.   * compliance with the License. You may obtain a copy of the License in
  10.   * the legal folder of your Openbravo installation.
  11.   * Software distributed under the License is distributed on an
  12.   * "AS IS" basis, WITHOUT WARRANTY OF ANY KIND, either express or
  13.   * implied. See the License for the specific language governing rights
  14.   * and limitations under the License.
  15.   * The Original Code is  Compiere  ERP &  Business Solution
  16.   * The Initial Developer of the Original Code is Jorg Janke and ComPiere, Inc.
  17.   * Portions created by Jorg Janke are Copyright (C) 1999-2001 Jorg Janke,
  18.   * parts created by ComPiere are Copyright (C) ComPiere, Inc.;
  19.   * All Rights Reserved.
  20.   * Contributor(s): Openbravo SLU
  21.   * Contributions are Copyright (C) 2001-2017 Openbravo, S.L.U.
  22.   *
  23.   * Specifically, this derivative work is based upon the following Compiere
  24.   * file and version.
  25.   *************************************************************************
  26.   * $Id: M_Production_Run.sql,v 1.4 2003/09/05 04:58:06 jjanke Exp $
  27.   ***
  28.   * Title: Production of BOMs
  29.   * Description:
  30.   *  1) Creating ProductionLines when IsCreated = 'N'
  31.   *  2) Posting the Lines (optionally only when fully stocked)
  32.   ************************************************************************/
  33.   -- Logistice
  34.   v_ResultStr VARCHAR(2000):=''; --OBTG:VARCHAR2--
  35.   v_Message VARCHAR(2000):=''; --OBTG:VARCHAR2--
  36.   v_Record_ID VARCHAR(32); --OBTG:VARCHAR2--
  37.   v_Result NUMERIC:=1;
  38.   v_is_included NUMERIC:=0;
  39.   v_MovementDate TIMESTAMP;
  40.   v_available_period NUMERIC:=0;
  41.   v_is_ready AD_Org.IsReady%TYPE;
  42.   v_is_tr_allow AD_OrgType.IsTransactionsAllowed%TYPE;
  43.   v_isacctle AD_OrgType.IsAcctLegalEntity%TYPE;
  44.   -- Parameter
  45.   --TYPE RECORD IS REFCURSOR;
  46.     Cur_Parameter RECORD;
  47.     CUR_ProductionPlan RECORD;
  48.     CUR_PP RECORD;
  49.     CUR_PLineBOM RECORD;
  50.     CUR_BOM_PRODUCT RECORD;
  51.     CUR_PL_Post RECORD;
  52.   -- Parameter Variables
  53.   MustBeStocked CHAR(1) ;
  54.   v_IsCreated CHAR(1) ;
  55.   v_Processed VARCHAR(60) ; --OBTG:VARCHAR2--
  56.   v_Client_ID VARCHAR(32); --OBTG:VARCHAR2--
  57.   v_Org_ID VARCHAR(32); --OBTG:VARCHAR2--
  58.   --
  59.   v_Line NUMERIC;
  60.   v_Count NUMERIC;
  61.   p_User VARCHAR(32); --OBTG:VARCHAR2--
  62.   v_NegStockLocator VARCHAR(32); --OBTG:VARCHAR2--
  63.   v_NegStockWarehosue VARCHAR(32); --OBTG:VARCHAR2--
  64.   v_Product_Name m_product.name%TYPE;
  65.   -- Stocked BOMs
  66.   -- Proposed stock from given warehouse is priorized.
  67.   DECLARE CUR_STOCK CURSOR (v_ad_pinstance_id VARCHAR)  FOR
  68.       SELECT sd.m_product_id, sd.m_locator_id, sd.m_attributesetinstance_id,
  69.           sd.c_uom_id, sd.m_product_uom_id, u.stdprecision,
  70.           ms.quantity AS qty, ms.qtyorder AS qtyorder,
  71.           ms.priority, invs.overissue
  72.       FROM m_stock_proposed ms
  73.             LEFT JOIN m_storage_detail sd ON ms.m_storage_detail_id = sd.m_storage_detail_id
  74.             LEFT JOIN m_product_uom pu ON sd.m_product_uom_id = pu.m_product_uom_id
  75.             LEFT JOIN c_uom u ON pu.c_uom_id = u.c_uom_id
  76.             LEFT JOIN m_locator l ON sd.m_locator_id = l.m_locator_id
  77.             JOIN m_inventorystatus invs ON invs.m_inventorystatus_id = l.m_inventorystatus_id
  78.       WHERE ms.ad_pinstance_id = v_ad_pinstance_id
  79.       ORDER BY ms.priority;
  80.   v_storage RECORD; --OBTG:CUR_STOCK--
  81.   NEXT_PRODUCT BOOLEAN:=false;
  82.   CUR_STOCK_ISOPEN BOOLEAN:=false;
  83. BEGIN
  84.   --  Update AD_PInstance
  85.   RAISE NOTICE '%','Updating PInstance - Processing ' || PInstance_ID ;
  86.   v_ResultStr:='PInstanceNotFound';
  87.   PERFORM AD_UPDATE_PINSTANCE(PInstance_ID, NULL, 'Y', NULL, NULL) ;
  88. BEGIN --BODY
  89.   -- Get Parameters
  90.   v_ResultStr:='ReadingParameters';
  91.   FOR Cur_Parameter IN (
  92.       SELECT i.Record_ID, i.AD_User_ID, p.ParameterName,
  93.           p.P_String, p.P_Number, p.P_Date
  94.       FROM AD_ClientInfo ci JOIN AD_PInstance i ON ci.ad_client_id=i.ad_client_id
  95.             LEFT JOIN AD_PInstance_Para p ON i.AD_PInstance_ID=p.AD_PInstance_ID
  96.       WHERE i.AD_PInstance_ID=PInstance_ID
  97.       ORDER BY p.SeqNo
  98.   ) LOOP
  99.     v_Record_ID := Cur_Parameter.Record_ID;
  100.     p_User := Cur_Parameter.AD_User_ID;
  101.     IF (Cur_Parameter.ParameterName = 'MustBeStocked') THEN
  102.       MustBeStocked:=Cur_Parameter.P_String;
  103.       RAISE NOTICE '%','  MustBeStocked=' || MustBeStocked ;
  104.     ELSE
  105.       RAISE NOTICE '%','*** Unknown Parameter=' || Cur_Parameter.ParameterName ;
  106.     END IF;
  107.   END LOOP; -- Get Parameter
  108.   RAISE NOTICE '%','  Record_ID=' || v_Record_ID ;
  109.   -- Processing:1:2:3 Lock :4:5:6:7
  110.   -- TODO
  111.   /**
  112.   * Get Info + Lock
  113.   */
  114.   v_ResultStr:='ReadingRecord';
  115.   SELECT IsCreated, Processed, AD_Client_ID, AD_Org_ID, MovementDate
  116.     INTO v_IsCreated, v_Processed, v_Client_ID, v_Org_ID, v_MovementDate
  117.   FROM M_PRODUCTION
  118.   WHERE M_Production_ID=v_Record_ID  FOR UPDATE;
  119.   /**
  120.   * No Action
  121.   */
  122.   IF (v_Processed <> 'N') THEN
  123.     v_Message:='@AlreadyPosted@';
  124.     RAISE EXCEPTION '%', v_Message; --OBTG:-20000--
  125.   END IF;
  126.   /**************************************************************************
  127.   * Create Lines
  128.   */
  129.   /***************************************************************************/
  130.   -- Check the header belongs to a organization where transactions are posible and ready to use
  131.   SELECT AD_Org.IsReady, Ad_OrgType.IsTransactionsAllowed
  132.     INTO v_is_ready, v_is_tr_allow
  133.   FROM M_PRODUCTION, AD_Org, AD_OrgType
  134.   WHERE AD_Org.AD_Org_ID=M_PRODUCTION.AD_Org_ID
  135.     AND AD_Org.AD_OrgType_ID=AD_OrgType.AD_OrgType_ID
  136.     AND M_PRODUCTION.M_PRODUCTION_ID=v_Record_ID;
  137.   IF (v_is_ready='N') THEN
  138.     RAISE EXCEPTION '%', '@OrgHeaderNotReady@'; --OBTG:-20000--
  139.   END IF;
  140.   IF (v_is_tr_allow='N') THEN
  141.     RAISE EXCEPTION '%', '@OrgHeaderNotTransAllowed@'; --OBTG:-20000--
  142.   END IF;
  143.  
  144.   -- Check the lines belong to the same business unit or legal entity as the header    
  145.   SELECT AD_ORG_CHK_DOCUMENTS('M_PRODUCTION', 'M_PRODUCTIONPLAN', v_Record_ID, 'M_PRODUCTION_ID', 'M_PRODUCTION_ID') INTO v_is_included FROM dual;
  146.   IF (v_is_included = -1) THEN
  147.     RAISE EXCEPTION '%', '@LinesAndHeaderDifferentLEorBU@'; --OBTG:-20000--
  148.   END IF;
  149.   FOR CUR_PP IN (
  150.       SELECT M_PRODUCTIONPLAN_ID
  151.       FROM M_PRODUCTIONPLAN
  152.       WHERE M_PRODUCTION_ID = v_Record_ID
  153.   ) LOOP
  154.     SELECT AD_ORG_CHK_DOCUMENTS('M_PRODUCTIONPLAN', 'M_PRODUCTIONLINE', CUR_PP.M_PRODUCTIONPLAN_ID, 'M_PRODUCTIONPLAN_ID', 'M_PRODUCTIONPLAN_ID') INTO v_is_included FROM dual;
  155.     IF (v_is_included = -1) THEN
  156.       RAISE EXCEPTION '%', '@LinesAndHeaderDifferentLEorBU@'; --OBTG:-20000--
  157.     END IF;
  158.   END LOOP;
  159.  
  160.   -- Check the period control is opened (only if it is legal entity with accounting)
  161.   -- Gets the BU or LE of the document
  162.   SELECT AD_OrgType.IsAcctLegalEntity INTO v_isacctle
  163.   FROM AD_OrgType, AD_Org
  164.   WHERE AD_Org.AD_OrgType_ID = AD_OrgType.AD_OrgType_ID
  165.     AND AD_Org.AD_Org_ID = AD_GET_DOC_LE_BU('M_PRODUCTION', v_Record_ID, 'M_PRODUCTION_ID', 'LE');
  166.  
  167.   IF (v_isacctle='Y') THEN
  168.     SELECT C_CHK_OPEN_PERIOD(v_Org_ID, v_MovementDate, 'MMP', NULL)  INTO v_available_period FROM DUAL;
  169.  
  170.     IF (v_available_period<>1) THEN
  171.       RAISE EXCEPTION '%', '@PeriodNotAvailable@'; --OBTG:-20000--
  172.     END IF;
  173.   END IF;
  174.  
  175.   IF (v_IsCreated <> 'Y') THEN
  176.     -- For every Production Plan
  177.     FOR CUR_PP IN (
  178.         SELECT M_PRODUCTIONPLAN.*, M_PRODUCT.C_UOM_ID,
  179.             (CASE WHEN M_PRODUCT.ATTRSETVALUETYPE='D' THEN M_PRODUCT.M_AttributeSetInstance_ID ELSE NULL END) AS M_AttributeSetInstance_ID
  180.         FROM M_PRODUCTIONPLAN, M_PRODUCT
  181.         WHERE M_PRODUCTIONPLAN.M_Product_ID=M_PRODUCT.M_Product_ID
  182.           AND M_PRODUCTIONPLAN.M_Production_ID=v_Record_ID
  183.         ORDER BY M_PRODUCTIONPLAN.Line, M_PRODUCTIONPLAN.M_Product_ID
  184.     ) LOOP
  185.       IF (CUR_PP.M_Locator_ID IS NULL) THEN
  186.         RAISE EXCEPTION '%', '@ProductionPlanLocatorNeeded@'; --OBTG:-20000--
  187.       END IF;
  188.       -- Delete prior lines
  189.       DELETE
  190.       FROM M_PRODUCTIONLINE
  191.       WHERE M_ProductionPlan_ID=CUR_PP.M_ProductionPlan_ID;
  192.       -- Create BOM Line
  193.       v_ResultStr:='CreatingLine BOM';
  194.       v_Line:=10; -- OriginLine
  195.       INSERT INTO M_PRODUCTIONLINE (
  196.           M_ProductionLine_ID, M_ProductionPlan_ID, Line, AD_Client_ID,
  197.           AD_Org_ID, IsActive, Created, CreatedBy,
  198.           Updated, UpdatedBy, M_Product_ID, MovementQty,
  199.           M_Locator_ID, Description, C_UOM_ID,
  200.           M_AttributeSetInstance_ID
  201.       ) VALUES (
  202.           get_uuid(), CUR_PP.M_ProductionPlan_ID, v_Line, CUR_PP.AD_Client_ID,
  203.           CUR_PP.AD_Org_ID, 'Y', TO_DATE(NOW()), p_User,
  204.           TO_DATE(NOW()), p_User, CUR_PP.M_Product_ID, CUR_PP.ProductionQty,
  205.           CUR_PP.M_Locator_ID, CUR_PP.Description, CUR_PP.C_UOM_ID,
  206.           CUR_PP.M_AttributeSetInstance_ID
  207.       );
  208.     END LOOP;
  209.     --Creating BOM Lines
  210.     DECLARE
  211.       v_Product_old VARCHAR(32); --OBTG:VARCHAR2--
  212.       v_Warehouse_old VARCHAR(32); --OBTG:VARCHAR2--
  213.       v_UOM_old VARCHAR(32); --OBTG:VARCHAR2--
  214.       v_Qty NUMERIC;
  215.       v_QtyStorage NUMERIC:=0;
  216.       v_QtyAcumulated NUMERIC;
  217.       v_QtyOrder NUMERIC;
  218.       v_QtyOrderRate NUMERIC;
  219.       v_ProductionLineCount NUMERIC;
  220.       v_pinstance_id VARCHAR(32); --OBTG:VARCHAR2--
  221.       CUR_BOM RECORD;
  222.     BEGIN
  223.       FOR CUR_BOM IN (
  224.           SELECT pb.*,
  225.               p.C_UOM_ID, p.IsStocked, pp.M_LOCATOR_ID, pp.AD_Org_ID AS ORG_ID,
  226.               pp.ProductionQty, pp.M_ProductionPlan_ID, pp.AD_Client_ID AS Client_ID, p.name as pname,
  227.               l.m_warehouse_id
  228.           FROM M_PRODUCT_BOM pb
  229.               JOIN M_PRODUCT p ON pb.M_ProductBOM_ID=p.M_Product_ID
  230.               JOIN M_PRODUCTIONPLAN pp ON pb.M_Product_ID=pp.M_PRODUCT_ID
  231.               JOIN M_LOCATOR l ON pp.m_locator_id = l.m_locator_id
  232.         WHERE pp.M_PRODUCTION_ID=v_Record_ID
  233.           AND pb.isactive='Y'
  234.         ORDER BY pb.M_PRODUCTBOM_ID, pb.Line
  235.       ) LOOP
  236.         v_ResultStr:='CreatingLine Products';
  237.         IF (CUR_BOM.IsStocked = 'Y') THEN
  238.           v_QtyAcumulated:=0;
  239.           IF ((NOT CUR_STOCK_ISOPEN)
  240.               OR (v_Product_old <> CUR_BOM.M_ProductBOM_ID OR v_Warehouse_old <> cur_bom.m_warehouse_id OR v_UOM_old <> CUR_BOM.C_UOM_ID)) THEN
  241.             NEXT_PRODUCT:=false;
  242.             v_product_old := cur_bom.m_productbom_id;
  243.             v_warehouse_old := cur_bom.m_warehouse_id;
  244.             v_uom_old := cur_bom.c_uom_id;
  245.             IF (CUR_STOCK_ISOPEN) THEN
  246.               CLOSE CUR_STOCK;
  247.               CUR_STOCK_ISOPEN:=false;
  248.             END IF;
  249.            
  250.             -- Call M_GET_STOCK
  251.             DECLARE
  252.               v_pinstance_result AD_PInstance.result%TYPE;
  253.               v_pinstance_msg AD_PInstance.errormsg%TYPE;
  254.             BEGIN
  255.               v_pinstance_id := get_uuid();
  256.              SELECT * INTO  v_pinstance_result, v_pinstance_msg FROM M_GET_STOCK_PARAM(v_pinstance_id, v_record_id, null, v_Product_old, null, null, v_Warehouse_old, cur_bom.org_id, null, p_user, v_client_id, null, v_UOM_old, null, null, null, 10, '137', null, 'N', 'Y', null, null);
  257.               -- Check result
  258.               IF (v_pinstance_result = 0) THEN
  259.                 -- Error on m_get_stock
  260.                 RAISE EXCEPTION '%', v_pinstance_msg; --OBTG:-20000--
  261.               END IF;
  262.             END; -- End Call M_GET_STOCK
  263.            
  264.             OPEN CUR_STOCK(v_pinstance_id);
  265.             CUR_STOCK_ISOPEN:=true;
  266.             FETCH CUR_STOCK INTO v_storage;
  267.             IF ( NOT FOUND ) THEN --OBTG:CUR_STOCK--
  268.               NEXT_PRODUCT:=true;
  269.             END IF;
  270.             v_qtystorage:=v_storage.qty;
  271.           END IF;
  272.           IF (NOT NEXT_PRODUCT) THEN
  273.             LOOP          
  274.               IF (v_storage.OVERISSUE = 'Y' AND v_NegStockLocator IS NULL) THEN
  275.                 v_NegStockLocator:= v_storage.m_locator_id;
  276.               END IF;
  277.  
  278.               v_Qty := LEAST(v_QtyStorage, CUR_BOM.ProductionQty * CUR_BOM.BOMQty - v_QtyAcumulated) ;
  279.               v_QtyStorage := v_QtyStorage - v_Qty;
  280.               v_QtyAcumulated := v_QtyAcumulated + v_Qty;
  281.               v_QtyOrder := ROUND(v_storage.QtyOrder*(v_Qty/v_storage.Qty), v_storage.stdprecision);
  282.               SELECT COALESCE(MAX(Line), 0) + 10 INTO v_Line
  283.               FROM M_PRODUCTIONLINE
  284.               WHERE M_ProductionPlan_ID=CUR_BOM.M_ProductionPlan_ID;
  285.               INSERT INTO M_PRODUCTIONLINE (
  286.                   M_ProductionLine_ID, M_ProductionPlan_ID, Line, AD_Client_ID,
  287.                   AD_Org_ID, IsActive, Created, CreatedBy,
  288.                   Updated, UpdatedBy, M_Product_ID, C_UOM_ID,
  289.                   MovementQty, M_Locator_ID,
  290.                   M_AttributeSetInstance_ID,
  291.                   M_Product_UOM_ID,
  292.                   QuantityOrder
  293.               ) VALUES (
  294.                   get_uuid(), CUR_BOM.M_ProductionPlan_ID, v_Line, CUR_BOM.Client_ID,
  295.                   CUR_BOM.Org_ID, 'Y', TO_DATE(NOW()), p_User,
  296.                   TO_DATE(NOW()), p_User, CUR_BOM.M_ProductBOM_ID, CUR_BOM.C_UOM_ID,
  297.                   -v_Qty, v_storage.M_Locator_ID,
  298.                   (CASE WHEN (SELECT ATTRSETVALUETYPE FROM M_PRODUCT WHERE M_PRODUCT_ID=CUR_BOM.M_ProductBOM_ID)='F' THEN NULL ELSE v_storage.M_AttributeSetInstance_ID END),
  299.                   v_storage.M_Product_UOM_ID,
  300.                   -v_QtyOrder
  301.               );
  302.               IF (v_QtyAcumulated >= CUR_BOM.ProductionQty*CUR_BOM.BOMQty) THEN
  303.                 EXIT;
  304.               END IF;
  305.               v_QtyStorage:=0;
  306.               v_ResultStr:='FetchingData';
  307.               FETCH CUR_STOCK INTO v_storage;
  308.               IF ( NOT FOUND ) THEN --OBTG:CUR_STOCK--
  309.                 CLOSE CUR_STOCK;
  310.                 CUR_STOCK_ISOPEN:=false;
  311.                 EXIT;
  312.               END IF;
  313.               EXIT WHEN  NOT FOUND ; --OBTG:CUR_STOCK--
  314.               v_QtyStorage:=v_storage.Qty;
  315.             END LOOP;
  316.           END IF; --NEXT_PRODUCT
  317.         ELSE
  318.           SELECT COALESCE(MAX(Line), 0) + 10
  319.           INTO v_Line
  320.           FROM M_PRODUCTIONLINE
  321.           WHERE M_ProductionPlan_ID=CUR_BOM.M_ProductionPlan_ID;
  322.           INSERT INTO M_PRODUCTIONLINE (
  323.               M_ProductionLine_ID, M_ProductionPlan_ID, Line, AD_Client_ID,
  324.               AD_Org_ID, IsActive, Created, CreatedBy,
  325.               Updated, UpdatedBy, M_Product_ID, MovementQty,
  326.               M_Locator_ID, C_UOM_ID
  327.           ) VALUES (
  328.               get_uuid(), CUR_BOM.M_ProductionPlan_ID, v_Line, CUR_BOM.Client_ID,
  329.               CUR_BOM.Org_ID, 'Y', TO_DATE(NOW()), p_User,
  330.               TO_DATE(NOW()), p_User, CUR_BOM.M_ProductBOM_ID, -CUR_BOM.ProductionQty*CUR_BOM.BOMQty,
  331.               CUR_BOM.M_Locator_ID, CUR_BOM.C_UOM_ID
  332.           );
  333.         END IF;
  334.         v_Line:=v_Line;
  335.         IF (v_QtyAcumulated < CUR_BOM.BOMQTY*CUR_BOM.ProductionQty) THEN
  336.           IF (MustBeStocked='Y') THEN
  337.             v_Message := '@NotEnoughStocked@: ' || CUR_BOM.pname || ' ' || v_QtyAcumulated || ' / '|| CUR_BOM.BOMQTY*CUR_BOM.ProductionQty;
  338.             RAISE EXCEPTION '%', v_Message; --OBTG:-20000--
  339.           ELSE
  340.             IF (v_NegStockLocator IS NULL) THEN
  341.               -- Get Locator with negative Stock that belongs to the same Warehosue
  342.               SELECT m_warehouse_id
  343.               INTO v_NegStockWarehosue
  344.               FROM m_locator
  345.              WHERE m_locator_id = (SELECT m_locator_id
  346.                                    FROM M_PRODUCTIONPLAN
  347.                                    WHERE M_ProductionPlan_ID=CUR_BOM.M_ProductionPlan_ID);
  348.        
  349.               SELECT MIN(l.m_locator_id)
  350.               INTO v_NegStockLocator
  351.               FROM m_locator l
  352.               JOIN m_inventorystatus invs ON l.m_inventorystatus_id = invs.m_inventorystatus_id
  353.               WHERE l.m_warehouse_id = v_NegStockWarehosue
  354.               AND invs.overissue = 'Y'
  355.               AND l.isactive= 'Y'
  356.               AND priorityno = (SELECT MIN(priorityno)
  357.                                 FROM m_locator l
  358.                                 JOIN m_inventorystatus invs ON l.m_inventorystatus_id = invs.m_inventorystatus_id
  359.                                 WHERE l.m_warehouse_id = v_NegStockWarehosue
  360.                                 AND invs.overissue = 'Y'
  361.                                 AND l.isactive='Y');
  362.             END IF;        
  363.            
  364.             -- If there is a Storage Bin that allows negative stock and MustBeStocked is disabled and there is not enough stock,
  365.             -- pending quantity will be created for the same locator as production plan product, keeping a negative stock
  366.             IF (v_NegStockLocator IS NOT NULL) THEN  
  367.            
  368.               -- Check if exists a production line for this product with the same locator
  369.               SELECT count(M_ProductionLine_ID)
  370.               INTO v_ProductionLineCount
  371.               FROM M_PRODUCTIONLINE
  372.               WHERE M_ProductionPlan_ID=CUR_BOM.M_ProductionPlan_ID
  373.               AND M_Product_ID=CUR_BOM.M_ProductBOM_ID
  374.               AND M_Locator_ID=v_NegStockLocator;
  375.  
  376.               -- If exists update it            
  377.               IF (v_ProductionLineCount <> 0) THEN
  378.                
  379.                 SELECT QuantityOrder / CASE WHEN (MovementQty <> 0) THEN MovementQty ELSE 1 END
  380.                 INTO v_QtyOrderRate
  381.                 FROM M_PRODUCTIONLINE
  382.                 WHERE M_ProductionPlan_ID=CUR_BOM.M_ProductionPlan_ID
  383.                 AND M_Product_ID=CUR_BOM.M_ProductBOM_ID
  384.                 AND M_Locator_ID=v_NegStockLocator;              
  385.                
  386.                 UPDATE M_PRODUCTIONLINE
  387.                 SET MovementQty = MovementQty - (CUR_BOM.BOMQTY*CUR_BOM.ProductionQty - v_QtyAcumulated),
  388.                 QuantityOrder = v_QtyOrderRate * (MovementQty - (CUR_BOM.BOMQTY*CUR_BOM.ProductionQty - v_QtyAcumulated))
  389.                 WHERE M_ProductionPlan_ID=CUR_BOM.M_ProductionPlan_ID
  390.                 AND M_Product_ID=CUR_BOM.M_ProductBOM_ID
  391.                 AND M_Locator_ID=v_NegStockLocator;
  392.  
  393.               -- If not exists, insert a new production line
  394.               ELSE
  395.                    
  396.                 SELECT COALESCE(MAX(Line), 0) + 10 INTO v_Line
  397.                 FROM M_PRODUCTIONLINE
  398.                 WHERE M_ProductionPlan_ID=CUR_BOM.M_ProductionPlan_ID;        
  399.                
  400.                 INSERT INTO M_PRODUCTIONLINE (
  401.                   M_ProductionLine_ID, M_ProductionPlan_ID, Line, AD_Client_ID,
  402.                   AD_Org_ID, IsActive, Created, CreatedBy,
  403.                   Updated, UpdatedBy, M_Product_ID, C_UOM_ID,
  404.                   MovementQty, M_Locator_ID
  405.               ) VALUES (
  406.                   get_uuid(), CUR_BOM.M_ProductionPlan_ID, v_Line, CUR_BOM.Client_ID,
  407.                   CUR_BOM.Org_ID, 'Y', TO_DATE(NOW()), p_User,
  408.                   TO_DATE(NOW()), p_User, CUR_BOM.M_ProductBOM_ID, CUR_BOM.C_UOM_ID,
  409.                   - (CUR_BOM.BOMQTY*CUR_BOM.ProductionQty - v_QtyAcumulated), v_NegStockLocator                  
  410.               );
  411.              
  412.               END IF;          
  413.             END IF;
  414.           END IF;  
  415.         END IF;
  416.         IF (CUR_BOM.ProductionQty <= 0) THEN
  417.           v_Message := '@NegativeBOMProductionQty@';
  418.           RAISE EXCEPTION '%', v_Message; --OBTG:-20000--
  419.         END IF;
  420.       END LOOP;
  421.       IF (CUR_STOCK_ISOPEN) THEN
  422.         CLOSE CUR_STOCK;
  423.         CUR_STOCK_ISOPEN := false;
  424.       END IF;
  425.     END; --END OF DECLARE FOR BOM PRODUCTS INSERTION
  426.     -- While we have BOMs
  427.     LOOP
  428.       -- Are there non-stored BOMs to list details:8
  429.       v_ResultStr:='CreatingLine CheckBOM';
  430.       SELECT COUNT(*) INTO v_count
  431.       FROM M_PRODUCTIONLINE pl,
  432.         M_PRODUCT p,
  433.         M_PRODUCTIONPLAN pp
  434.       WHERE pl.M_Product_ID=p.M_Product_ID
  435.         AND pl.M_ProductionPlan_ID=pp.M_ProductionPlan_ID
  436.         AND pp.M_PRODUCTION_ID=v_Record_ID
  437.         AND pl.Line<>10 -- Origin Line
  438.         AND p.IsBOM='Y'
  439.         AND p.IsStocked='N';
  440.       -- Nothing to do
  441.       EXIT WHEN(v_count=0) ;
  442.       --
  443.       -- Resolve BOMs in ProductLine which are not stocked
  444.       FOR CUR_PLineBOM IN (
  445.           SELECT pl.M_ProductionLine_ID, pl.Line, pl.M_Product_ID, pl.MovementQty,
  446.               pp.M_LOCATOR_ID, pp.AD_Org_ID AS ORG_ID, pp.ProductionQty, pp.M_ProductionPlan_ID,
  447.               pp.AD_Client_ID AS Client_ID
  448.           FROM M_PRODUCTIONLINE pl, M_PRODUCT p, M_PRODUCTIONPLAN pp
  449.         WHERE pl.M_ProductionPlan_ID=pp.M_ProductionPlan_ID
  450.           AND pp.M_Production_ID=v_Record_ID
  451.           AND pl.M_Product_ID=p.M_Product_ID
  452.           AND pl.Line<>10 -- Origin Line
  453.           AND p.IsBOM='Y'
  454.           AND p.IsStocked='N'
  455.       ) LOOP
  456.         v_ResultStr:='CreatingLineBOM Resolution';
  457.         v_Line:=CUR_PLineBOM.Line;
  458.         -- Resolve BOM Line in product line
  459.         FOR CUR_BOM_PRODUCT IN (
  460.             SELECT pb.*, p.C_UOM_ID, p.IsStocked
  461.             FROM M_PRODUCT_BOM pb, M_PRODUCT p
  462.             WHERE pb.M_ProductBOM_ID=p.M_Product_ID
  463.               AND pb.M_Product_ID=CUR_PLineBOM.M_Product_ID
  464.               AND pb.isactive='Y'
  465.             ORDER BY pb.M_PRODUCTBOM_ID, pb.Line
  466.         ) LOOP
  467.           v_ResultStr:='CreatingLine Products2';
  468.           SELECT COALESCE(MAX(Line), 0) + 10 INTO v_Line
  469.           FROM M_PRODUCTIONLINE
  470.           WHERE M_ProductionPlan_ID=CUR_PLineBOM.M_ProductionPlan_ID;
  471.           INSERT INTO M_PRODUCTIONLINE (
  472.               M_ProductionLine_ID, M_ProductionPlan_ID, Line, AD_Client_ID,
  473.               AD_Org_ID, IsActive, Created, CreatedBy,
  474.               Updated, UpdatedBy, M_Product_ID, MovementQty,
  475.               M_Locator_ID, C_UOM_ID
  476.           ) VALUES (
  477.               get_uuid(), CUR_PLineBOM.M_ProductionPlan_ID, v_Line, CUR_PLineBOM.Client_ID,
  478.               CUR_PLineBOM.Org_ID, 'Y', TO_DATE(NOW()), p_User,
  479.               TO_DATE(NOW()), p_User, CUR_BOM_PRODUCT.M_ProductBOM_ID, CUR_PLineBOM.MovementQty*CUR_BOM_PRODUCT.BOMQty,
  480.               CUR_PLineBOM.M_Locator_ID, CUR_BOM_PRODUCT.C_UOM_ID
  481.           );
  482.         END LOOP;
  483.         -- Delete BOM line
  484.         DELETE
  485.         FROM M_PRODUCTIONLINE
  486.         WHERE M_ProductionLine_ID=CUR_PLineBOM.M_ProductionLine_ID;
  487.       END LOOP;
  488.     END LOOP; -- While we have BOMs
  489.     -- Modifying locator to have sufficient stock
  490.     -- Indicate that it is Created
  491.     UPDATE M_PRODUCTION  SET IsCreated='Y',Updated=TO_DATE(NOW()),UpdatedBy=p_User  WHERE M_Production_ID=v_Record_ID;
  492.   /**************************************************************************
  493.   * Post Lines
  494.   */
  495.   ELSE
  496.     v_ResultStr:='CheckingRestrictions';
  497.     SELECT COUNT(*) INTO v_Count
  498.     FROM M_PRODUCTIONPLAN PP, M_PRODUCTIONLINE PL, M_PRODUCT P
  499.     WHERE PL.M_PRODUCT_ID=P.M_PRODUCT_ID
  500.       AND P.M_ATTRIBUTESET_ID IS NOT NULL
  501.       AND (P.ATTRSETVALUETYPE IS NULL OR P.ATTRSETVALUETYPE <> 'F')
  502.       AND (SELECT ISONEATTRSETVALREQUIRED FROM M_ATTRIBUTESET WHERE M_ATTRIBUTESET_ID = P.M_ATTRIBUTESET_ID) = 'Y'
  503.       AND COALESCE(PL.M_ATTRIBUTESETINSTANCE_ID, '0') = '0'
  504.       AND PL.M_ProductionPlan_ID=pp.M_ProductionPlan_ID
  505.       AND pp.M_Production_ID=v_Record_ID;
  506.     IF (v_Count <> 0) THEN
  507.       SELECT max(P.name) INTO v_Product_Name
  508.       FROM M_PRODUCTIONPLAN PP, M_PRODUCTIONLINE PL, M_PRODUCT P
  509.       WHERE PL.M_PRODUCT_ID=P.M_PRODUCT_ID
  510.         AND P.M_ATTRIBUTESET_ID IS NOT NULL
  511.         AND (P.ATTRSETVALUETYPE IS NULL OR P.ATTRSETVALUETYPE <> 'F')
  512.         AND (SELECT ISONEATTRSETVALREQUIRED FROM M_ATTRIBUTESET WHERE M_ATTRIBUTESET_ID = P.M_ATTRIBUTESET_ID) = 'Y'
  513.         AND COALESCE(PL.M_ATTRIBUTESETINSTANCE_ID, '0') = '0'
  514.         AND PL.M_ProductionPlan_ID=pp.M_ProductionPlan_ID
  515.         AND pp.M_Production_ID=v_Record_ID;
  516.       v_Message:='@Product@'||' "' ||v_Product_Name ||'" ' || '@ProductWithoutAttributeSet@';
  517.       RAISE EXCEPTION '%', v_Message; --OBTG:-20000--
  518.     END IF;
  519.  
  520.     SELECT COUNT(M_ProductionPlan_ID)
  521.     INTO v_count
  522.     FROM M_ProductionPlan pp
  523.     WHERE pp.M_Production_ID = v_Record_ID
  524.     AND NOT EXISTS (SELECT 1 FROM M_ProductionLine WHERE M_ProductionPlan_ID = pp.M_ProductionPlan_ID AND MovementQty > 0);
  525.  
  526.     v_Message := NULL;      
  527.     IF(v_count <> 0) THEN
  528.       FOR CUR_ProductionPlan IN (
  529.     SELECT DISTINCT(pp.line)
  530.     FROM M_ProductionPlan pp
  531.     WHERE pp.M_Production_ID = v_Record_ID
  532.     AND NOT EXISTS (SELECT 1 FROM M_ProductionLine WHERE M_ProductionPlan_ID = pp.M_ProductionPlan_ID AND MovementQty > 0)
  533.     ORDER BY Line
  534.         )
  535.       LOOP
  536.         IF v_Message IS NULL THEN
  537.           v_Message := CUR_ProductionPlan.line;
  538.         ELSE
  539.       v_Message := v_Message || ', ' || CUR_ProductionPlan.line;
  540.     END IF;
  541.       END LOOP;
  542.       v_Message := '@ProducedProductWithNegativeQty@' || ' @ReferProductionPlanLines@' || ': ' || v_Message;
  543.       RAISE EXCEPTION '%', v_Message; --OBTG:-20000--
  544.     END IF;  
  545.  
  546.     SELECT COUNT(M_ProductionPlan_ID)
  547.     INTO v_count
  548.     FROM M_ProductionPlan pp
  549.     WHERE pp.M_Production_ID = v_Record_ID
  550.     AND (SELECT COUNT(M_ProductionLine_ID) FROM M_ProductionLine WHERE M_ProductionPlan_ID = pp.M_ProductionPlan_ID AND movementQty > 0) > 1;
  551.    
  552.     IF (v_count <> 0) THEN
  553.       FOR CUR_ProductionPlan IN (
  554.     SELECT DISTINCT(pp.line)
  555.     FROM M_ProductionPlan pp
  556.     WHERE pp.M_Production_ID = v_Record_ID
  557.     AND (SELECT COUNT(M_ProductionLine_ID) FROM M_ProductionLine WHERE M_ProductionPlan_ID = pp.M_ProductionPlan_ID AND movementQty > 0) > 1
  558.     ORDER BY Line
  559.       )
  560.       LOOP
  561.         IF v_Message IS NULL THEN
  562.           v_Message := CUR_ProductionPlan.line;
  563.         ELSE
  564.       v_Message := v_Message || ', ' || CUR_ProductionPlan.line;
  565.     END IF;
  566.       END LOOP;
  567.       v_Message:= '@ConsumedProductWithPostiveQty@' || ' @ReferProductionPlanLines@' || ': ' || v_Message;
  568.       RAISE EXCEPTION '%', v_Message; --OBTG:-20000--
  569.     END IF;
  570.  
  571.     DECLARE
  572.         v_Message_ProductionRun VARCHAR(2000);
  573.         v_Message_ProductLine VARCHAR(2000);
  574.         BEGIN
  575.           FOR CUR_ProductionPlan IN
  576.             (SELECT pp.Line, pp.M_PRODUCTIONPLAN_ID
  577.             FROM M_PRODUCTION p, M_PRODUCTIONPLAN pp
  578.             WHERE p.M_Production_ID=pp.M_Production_ID
  579.             AND pp.M_Production_ID=v_Record_ID
  580.             ORDER BY pp.Line)
  581.           LOOP
  582.             FOR CUR_PL_Post IN
  583.               (SELECT pl.Line
  584.               FROM M_PRODUCTIONLINE pl, M_PRODUCT pr
  585.               WHERE Cur_ProductionPlan.M_ProductionPlan_ID=pl.M_ProductionPlan_ID
  586.               AND pl.M_PRODUCT_ID=pr.M_PRODUCT_ID
  587.               AND pr.ISACTIVE='N'
  588.               ORDER BY pl.Line)
  589.             LOOP
  590.               v_Message_ProductLine := COALESCE(v_Message_ProductLine, '') || CUR_PL_Post.line || ', ';
  591.             END LOOP;
  592.             IF (v_Message_ProductLine IS NOT NULL) THEN
  593.               v_Message_ProductionRun := COALESCE(v_Message_ProductionRun, '') || '@ProductionRunLine@' || Cur_ProductionPlan.line || ' @ProductLine@' || v_Message_ProductLine;
  594.               v_Message_ProductLine := NULL;
  595.             END IF;
  596.           END LOOP;
  597.           IF (v_Message_ProductionRun IS NOT NULL) THEN
  598.             RAISE EXCEPTION '%', v_Message_ProductionRun||'@InActiveProducts@'; --OBTG:-20000--
  599.           END IF;
  600.         END;
  601.    
  602.     SELECT count(*) INTO v_count
  603.     FROM dual
  604.     WHERE EXISTS (
  605.         SELECT 1
  606.         FROM m_productionplan pp
  607.             JOIN m_productionline pl ON pp.m_productionplan_id = pl.m_productionplan_id
  608.             JOIN m_product p ON pl.m_product_id = p.m_product_id
  609.         WHERE pp.m_production_id = v_record_id
  610.           AND p.isgeneric = 'Y');
  611.     IF (v_count > 0) THEN
  612.       SELECT max(p.name) INTO v_product_name
  613.       FROM m_productionplan pp
  614.           JOIN m_productionline pl ON pp.m_productionplan_id = pl.m_productionplan_id
  615.           JOIN m_product p ON pl.m_product_id = p.m_product_id
  616.       WHERE pp.m_production_id = v_record_id
  617.         AND p.isgeneric = 'Y';
  618.       RAISE EXCEPTION '%', '@CannotUseGenericProduct@ ' || v_product_Name; --OBTG:-20000--
  619.     END IF;
  620.  
  621.     -- All Production Lines
  622.     FOR CUR_PL_Post IN (
  623.         SELECT pl.M_ProductionLine_ID, pl.AD_Client_ID, pl.AD_Org_ID, p.MovementDate,
  624.             pl.M_Product_ID, pl.M_AttributeSetInstance_ID, pl.MovementQty, pl.M_Locator_ID,
  625.             pl.M_Product_UOM_ID, pl.QuantityOrder, pl.C_UOM_ID, pl.LINE
  626.         FROM M_PRODUCTION p, M_PRODUCTIONLINE pl, M_PRODUCTIONPLAN pp, M_PRODUCT pro
  627.         WHERE p.M_Production_ID=pp.M_Production_ID
  628.           AND pp.M_ProductionPlan_ID=pl.M_ProductionPlan_ID
  629.           AND pl.M_PRODUCT_ID = pro.M_PRODUCT_ID
  630.           AND pro.ISSTOCKED = 'Y'
  631.           AND pp.M_Production_ID=v_Record_ID
  632.         ORDER BY pp.Line, pl.Line
  633.     ) LOOP
  634.       -- M_ProductionLine_ID, AD_Client_ID, AD_Org_ID, MovementDate, M_Product_ID, MovementQty, M_Locator_ID
  635.       -- DBMS_OUTPUT.PUT_LINE('ProductionLine=' || pl.M_ProductionLine_ID);
  636.       -- DBMS_OUTPUT.PUT_LINE('  Qty=' || pl.MovementQty || ', OnHand=' || M_BOM_Qty_OnHand(pl.M_Product_ID, NULL, pl.M_Locator_ID));
  637.       -- Check Stock levels for reductions
  638.       IF (CUR_PL_Post.MovementQty<0 AND MustBeStocked<>'N' AND M_BOM_Qty_OnHand(CUR_PL_Post.M_Product_ID, NULL, CUR_PL_Post.M_Locator_ID) +CUR_PL_Post.MovementQty<0) THEN
  639.         SELECT '@NotEnoughStocked@: ' || Name INTO v_Message
  640.         FROM M_PRODUCT
  641.         WHERE M_Product_ID=CUR_PL_Post.M_Product_ID;
  642.         RAISE EXCEPTION '%', v_Message; --OBTG:-20000--
  643.       END IF;
  644.       -- Create Transaction Entry
  645.       v_ResultStr:='CreateTransaction';
  646.       INSERT INTO M_TRANSACTION (
  647.           M_Transaction_ID, M_ProductionLine_ID, AD_Client_ID, AD_Org_ID,
  648.           IsActive, Created, CreatedBy, Updated,
  649.           UpdatedBy, MovementType, M_Locator_ID, M_Product_ID,
  650.           M_AttributeSetInstance_ID,
  651.           MovementDate, MovementQty, M_Product_UOM_ID, QuantityOrder,
  652.           C_UOM_ID
  653.       ) VALUES (
  654.           get_uuid(), CUR_PL_Post.M_ProductionLine_ID, CUR_PL_Post.AD_Client_ID, CUR_PL_Post.AD_Org_ID,
  655.            'Y', TO_DATE(NOW()), p_User, TO_DATE(NOW()),
  656.           p_User, 'P+', CUR_PL_Post.M_Locator_ID, CUR_PL_Post.M_Product_ID,
  657.           COALESCE(CUR_PL_Post.M_AttributeSetInstance_ID, '0'), -- not distinguishing between assemby/disassembly
  658.           CUR_PL_Post.MovementDate, CUR_PL_Post.MovementQty, CUR_PL_Post.M_Product_UOM_ID, CUR_PL_Post.QuantityOrder,
  659.           CUR_PL_Post.C_UOM_ID
  660.       );
  661.       SELECT * INTO  v_Result, v_Message FROM M_Check_Stock(CUR_PL_Post.M_Product_ID, v_Client_ID, v_Org_ID, CUR_PL_Post.M_Locator_ID) ;
  662.       IF (v_Result = 0) THEN
  663.         v_Message:=v_Message || ' @Inline@ ' || CUR_PL_Post.line;
  664.         RAISE EXCEPTION '%', v_Message; --OBTG:-20000--
  665.       END IF;
  666.     END LOOP;
  667.     -- Indicate that we are done
  668.     UPDATE M_PRODUCTION
  669.     SET Processed='Y',
  670.         updated=TO_DATE(NOW()),
  671.         updatedby=p_User
  672.     WHERE M_Production_ID=v_Record_ID;
  673.   END IF;
  674.   ---- <<FINISH_PROCESS>>
  675.   --  Update AD_PInstance
  676.   RAISE NOTICE '%','Updating PInstance - Finished ' || v_Message ;
  677.   PERFORM AD_UPDATE_PINSTANCE(PInstance_ID, NULL, 'N', v_Result, v_Message) ;
  678.   RETURN;
  679. END; --BODY
  680. EXCEPTION
  681.   WHEN OTHERS THEN
  682.     RAISE NOTICE '%',v_ResultStr ;
  683.     v_ResultStr:= '@ERROR=' || SQLERRM;
  684.     RAISE NOTICE '%',v_ResultStr ;
  685.     -- ROLLBACK;
  686.     PERFORM AD_UPDATE_PINSTANCE(PInstance_ID, NULL, 'N', 0, v_ResultStr) ;
  687.     RETURN;
  688. END ; $function$;
Advertisement
Add Comment
Please, Sign In to add comment
Advertisement