src-db/database/model/functions/M_RESERVATION_CONSUMPTION.xml
author Gorka Ion Damián <gorkaion.damian@openbravo.com>
Thu, 25 Oct 2012 17:20:43 +0200
changeset 18663 157c92ecd0e2
parent 18661 2d0858b58e59
child 18689 a17b382229ce
permissions -rw-r--r--
[Reservations]Fix pg consistency issues.
<?xml version="1.0"?>
  <database name="FUNCTION M_RESERVATION_CONSUMPTION">
    <function name="M_RESERVATION_CONSUMPTION" type="NULL">
      <parameter name="p_reservation_id" type="VARCHAR" mode="in">
        <default/>
      </parameter>
      <parameter name="p_locator_id" type="VARCHAR" mode="in">
        <default/>
      </parameter>
      <parameter name="p_attributesetinstance_id" type="VARCHAR" mode="in">
        <default/>
      </parameter>
      <parameter name="p_qty" type="NUMERIC" mode="in">
        <default/>
      </parameter>
      <parameter name="p_user_id" type="VARCHAR" mode="in">
        <default/>
      </parameter>
      <parameter name="p_result" type="NUMERIC" mode="out">
        <default/>
      </parameter>
      <parameter name="p_message" type="VARCHAR" mode="out">
        <default/>
      </parameter>
      <body><![CDATA[/*************************************************************************
* The contents of this file are subject to the Openbravo  Public  License
* Version  1.1  (the  "License"),  being   the  Mozilla   Public  License
* Version 1.1  with a permitted attribution clause; you may not  use this
* file except in compliance with the License. You  may  obtain  a copy of
* the License at http://www.openbravo.com/legal/license.html
* Software distributed under the License  is  distributed  on  an "AS IS"
* basis, WITHOUT WARRANTY OF ANY KIND, either express or implied. See the
* License for the specific  language  governing  rights  and  limitations
* under the License.
* The Original Code is Openbravo ERP.
* The Initial Developer of the Original Code is Openbravo SLU
* All portions are Copyright (C) 2012 Openbravo SLU
* All Rights Reserved.
* Contributor(s):  ______________________________________.
************************************************************************/

  v_pendingtorelease    NUMBER;
  v_warehouse_id        VARCHAR2(32);
  v_product_id          VARCHAR2(32);
  v_uom_id              VARCHAR2(32);
  v_res_stock_id        VARCHAR2(32);
  v_storage_detail_id   VARCHAR2(32);
  v_dim_warehouse_id    VARCHAR2(32);
  v_dim_locator_id      VARCHAR2(32);
  v_dim_asi_id          VARCHAR2(32);
  v_res_status          M_RESERVATION.RES_STATUS%TYPE;
  v_this_notreserved    NUMBER;
  v_this_reservedqty    NUMBER;
  v_this_releasedqty    NUMBER;
  v_this_allocated      NUMBER;
  v_this_noalloc        NUMBER;
  v_notreservedstock    NUMBER;
  v_reservedbyothers    NUMBER;
  v_qtytorelease        NUMBER;
  v_qtytounreserve      NUMBER;
  v_qtytounreserve_aux  NUMBER;
  v_newreservedqty      NUMBER;
  v_availablestock      NUMBER;
  v_dummy               VARCHAR2(2000);

  TYPE RECORD IS REF CURSOR;
  cur_reserved_stock       RECORD;
  cur_not_allocated_stock  RECORD;
BEGIN
  SELECT r.m_product_id, r.c_uom_id, COALESCE(r.reservedqty, 0), COALESCE(r.releasedqty, 0), r.quantity - COALESCE(r.reservedqty, 0),
      COALESCE(SUM(alloc.quantity - COALESCE(alloc.releasedqty, 0)), 0),
      r.m_warehouse_id, r.m_locator_id, r.m_attributesetinstance_id, res_status
    INTO v_product_id, v_uom_id, v_this_reservedqty, v_this_releasedqty, v_this_notreserved,
      v_this_allocated,
      v_dim_warehouse_id, v_dim_locator_id, v_dim_asi_id, v_res_status
  FROM m_reservation r
      LEFT JOIN m_reservation_stock alloc ON r.m_reservation_id = alloc.m_reservation_id AND alloc.isallocated = 'Y'
  WHERE r.m_reservation_id = p_reservation_id
  GROUP BY r.m_product_id, r.c_uom_id, r.reservedqty, r.releasedqty, r.quantity,
      r.m_warehouse_id, r.m_locator_id, r.m_attributesetinstance_id;
  v_this_noalloc := v_this_reservedqty - v_this_allocated;

  IF (v_res_status = 'HO') THEN
    RAISE_APPLICATION_ERROR(-20000, '@CannotConsumeHoldReservation@');
  END IF;

  SELECT sd.qtyonhand - COALESCE(rs.reservedstock, 0), sd.m_storage_detail_id, loc.m_warehouse_id
    INTO v_notreservedstock, v_storage_detail_id, v_warehouse_id
  FROM m_storage_detail sd
    JOIN m_locator loc ON sd.m_locator_id = loc.m_locator_id
    LEFT JOIN  (
        SELECT SUM(rs.quantity - rs.releasedqty) AS reservedstock
        FROM m_reservation_stock rs
          JOIN m_reservation r ON rs.m_reservation_id = r.m_reservation_id
        WHERE r.m_product_id = v_product_id
          AND r.res_status NOT IN ('CL')
          AND r.c_uom_id = v_uom_id
          AND rs.m_locator_id = p_locator_id
          AND COALESCE(rs.m_attributesetinstance_id, '0') = COALESCE(p_attributesetinstance_id, '0')
      ) rs ON 1=1
  WHERE sd.m_product_id = v_product_id
    AND sd.c_uom_id = v_uom_id
    AND COALESCE(sd.m_attributesetinstance_id, '0') = COALESCE(p_attributesetinstance_id, '0')
    AND sd.m_locator_id = p_locator_id;


  IF (COALESCE(v_dim_warehouse_id, v_warehouse_id) != v_warehouse_id
      OR COALESCE(v_dim_locator_id, p_locator_id) != p_locator_id
      OR COALESCE(v_dim_asi_id, p_attributesetinstance_id) != p_attributesetinstance_id) THEN
    RAISE_APPLICATION_ERROR(-20000, '@WrongStockDimensionMismatch@');
  END IF;

  v_pendingtorelease := p_qty;
  IF (v_pendingtorelease > v_this_reservedqty - v_this_releasedqty) THEN
    v_pendingtorelease := v_this_reservedqty - v_this_releasedqty;
    p_result := 2;
    p_message := '@MoreQuantityToReleaseThanPending@';
  END IF;
  -- Release stock reserved in the reservation.
  FOR cur_reserved_stock IN (
      SELECT quantity - releasedqty AS reservedqty, m_reservation_stock_id, isallocated
      FROM m_reservation_stock
      WHERE m_locator_id = p_locator_id
        AND COALESCE(m_attributesetinstance_id, '0') = COALESCE(p_attributesetinstance_id, '0')
      ORDER BY CASE isallocated WHEN 'Y' THEN 0 ELSE 1 END
  ) LOOP
    v_qtytorelease := LEAST(cur_reserved_stock.reservedqty, v_pendingtorelease);
    UPDATE m_reservation_stock
    SET releasedqty = releasedqty + v_qtytorelease,
        updated = now(),
        updatedby = p_user_id
    WHERE m_reservation_stock_id = cur_reserved_stock.m_reservation_stock_id;
    v_this_releasedqty := v_this_releasedqty + v_qtytorelease;
    v_this_allocated := v_this_allocated - CASE cur_reserved_stock.isallocated WHEN 'Y' THEN v_qtytorelease ELSE 0 END;
    v_this_noalloc := v_this_noalloc - CASE cur_reserved_stock.isallocated WHEN 'N' THEN v_qtytorelease ELSE 0 END;

    v_pendingtorelease := v_pendingtorelease - v_qtytorelease;
    IF (v_pendingtorelease = 0) THEN
      -- Stock completely released from the reservation
      RETURN;
    END IF;
  END LOOP;

  IF (v_pendingtorelease > COALESCE(v_this_noalloc, 0) + COALESCE(v_this_notreserved, 0)) THEN
    -- There is still stock pending to release but is higher than the not allocated or not reserved quantity, as it is
    -- not possible to modify allocated reserved stock with a different dimension an exception is raised.
    RAISE_APPLICATION_ERROR(-20000, '@CannotModifyAllocatedReserve@');
  END IF;
  
  -- If exists not reserved stock reserve in current reservation.
  IF (v_notreservedstock >= 0) THEN
    -- Reserve available stock
    v_qtytorelease := LEAST(v_notreservedstock, v_pendingtorelease);

    IF (v_qtytorelease > COALESCE(v_this_notreserved, 0)) THEN
      --The new reserved stock is higher than the pending quantity to reserve, other reserved stock must be unreserved.
      v_qtytounreserve := v_qtytorelease - COALESCE(v_this_notreserved, 0);
      FOR cur_reserved_stock IN (
          SELECT m_reservation_stock_id, quantity - COALESCE(releasedqty, 0) AS reservedqty
          FROM m_reservation_stock
          WHERE m_reservation_id = p_reservation_id
            AND isallocated = 'N'
            AND quantity != releasedqty
      ) LOOP
        v_qtytounreserve_aux := LEAST(v_qtytounreserve, cur_reserved_stock.reservedqty);
        UPDATE m_reservation_stock
        SET quantity = quantity - v_qtytounreserve_aux
        WHERE m_reservation_stock_id = cur_reserved_stock.m_reservation_stock_id;
        v_qtytounreserve := v_qtytounreserve - v_qtytounreserve_aux;
        v_this_noalloc := v_this_noalloc - v_qtytounreserve_aux;
        v_this_notreserved := v_this_notreserved + v_qtytounreserve_aux;

        IF (v_qtytounreserve = 0) THEN
          EXIT;
        END IF;
      END LOOP;
    END IF;

    M_RESERVE_STOCK_MANUAL(p_reservation_id, 'SD', v_storage_detail_id, v_qtytorelease, p_user_id, v_res_stock_id);
    v_this_notreserved := v_this_notreserved - v_qtytorelease;
    v_this_noalloc := v_this_noalloc + v_qtytorelease;
    -- Release reserved stock
    UPDATE m_reservation_stock
    SET releasedqty = releasedqty + v_qtytorelease,
        updated = now(),
        updatedby = p_user_id
    WHERE m_reservation_stock_id = v_res_stock_id;

    v_this_releasedqty := v_this_releasedqty + v_qtytorelease;
    v_this_noalloc := v_this_noalloc - v_qtytorelease;

    v_pendingtorelease := v_pendingtorelease - v_qtytorelease;
    IF (v_pendingtorelease = 0) THEN
      -- Stock completely released from the reservation
      RETURN;
    END IF;
  END IF;

  -- Finally take other reservation's not allocated stock.
  FOR cur_not_allocated_stock IN (
      SELECT r.m_reservation_id, rs.quantity, rs.releasedqty, rs.m_reservation_stock_id, r.reservedqty, r.quantity as quantitytoreserve,
             r.ad_client_id, r.ad_org_id, r.m_product_id, r.c_uom_id, r.m_attributesetinstance_id, r.m_locator_id, r.m_warehouse_id,
             r.c_orderline_id
      FROM m_reservation_stock rs
          JOIN m_reservation r ON rs.m_reservation_id = r.m_reservation_id
      WHERE r.m_reservation_id != p_reservation_id
        AND r.m_product_id = v_product_id
        AND r.c_uom_id = v_uom_id
        AND rs.m_locator_id = p_locator_id
        AND COALESCE(rs.m_attributesetinstance_id, '0') = COALESCE(p_attributesetinstance_id, '0')
        AND rs.isallocated = 'N'
        AND r.res_status NOT IN ('HO', 'CL')
        AND rs.quantity != rs.releasedqty
  ) LOOP
    v_qtytorelease := LEAST(v_pendingtorelease, cur_not_allocated_stock.quantity - cur_not_allocated_stock.releasedqty);
    
    IF (v_qtytorelease > COALESCE(v_this_notreserved, 0)) THEN
      --The new reserved stock is higher than the pending quantity to reserve, other reserved stock must be unreserved.
      v_qtytounreserve := v_qtytorelease - COALESCE(v_this_notreserved, 0);
      FOR cur_reserved_stock IN (
          SELECT m_reservation_stock_id, quantity - COALESCE(releasedqty, 0) AS reservedqty
          FROM m_reservation_stock
          WHERE m_reservation_id = p_reservation_id
            AND isallocated = 'N'
            AND quantity != releasedqty
      ) LOOP
        v_qtytounreserve_aux := LEAST(v_qtytounreserve, cur_reserved_stock.reservedqty);
        UPDATE m_reservation_stock
        SET quantity = quantity - v_qtytounreserve_aux
        WHERE m_reservation_stock_id = cur_reserved_stock.m_reservation_stock_id;
        v_qtytounreserve := v_qtytounreserve - v_qtytounreserve_aux;
        v_this_noalloc := v_this_noalloc - v_qtytounreserve_aux;
        v_this_notreserved := v_this_notreserved + v_qtytounreserve_aux;

        IF (v_qtytounreserve = 0) THEN
          EXIT;
        END IF;
      END LOOP;
    END IF;
    
    UPDATE m_reservation_stock
    SET quantity = quantity - v_qtytorelease
    WHERE m_reservation_stock_id = cur_not_allocated_stock.m_reservation_stock_id;
    M_RESERVE_STOCK_MANUAL(p_reservation_id, 'SD', v_storage_detail_id, v_qtytorelease, p_user_id, v_res_stock_id);
    v_this_notreserved := v_this_notreserved - v_qtytorelease;
    v_this_noalloc := v_this_noalloc + v_qtytorelease;
    
    -- Call get stock to check availability
    DECLARE
      v_pinstance_result      AD_PInstance.result%TYPE;
      v_pinstance_msg         AD_PInstance.errormsg%TYPE;
      v_warehouse_rule_id     VARCHAR2(32);
      v_pinstance_id          VARCHAR2(32) := get_uuid();
    BEGIN
      INSERT INTO ad_pinstance (
          ad_pinstance_id, ad_process_id, record_id, isactive, 
          ad_user_id, ad_client_id, ad_org_id, created, createdby,
          updated, updatedby
      ) VALUES (
          v_pinstance_id, 'FF80818132C964E30132C9747257002E', p_reservation_id, 'Y',
          p_User_ID, cur_not_allocated_stock.ad_client_id, cur_not_allocated_stock.ad_Org_ID, now(), p_user_ID,
          now(), p_user_ID
      );
  
      AD_PINSTANCE_PARA_INSERT(v_pinstance_id, '10', 'AD_Client_ID', cur_not_allocated_stock.ad_client_id, null, null, null, null, null);
      AD_PINSTANCE_PARA_INSERT(v_pinstance_id, '20', 'AD_Org_ID', cur_not_allocated_stock.ad_org_id, null, null, null, null, null);
      AD_PINSTANCE_PARA_INSERT(v_pinstance_id, '30', 'M_Product_ID', cur_not_allocated_stock.m_product_id, null, null, null, null, null);
      AD_PINSTANCE_PARA_INSERT(v_pinstance_id, '40', 'C_Uom_ID', cur_not_allocated_stock.c_uom_id, null, null, null, null, null);
      --AD_PINSTANCE_PARA_INSERT(v_pinstance_id, '50', 'M_Product_Uom_ID', v_Product_UOM_old, null, null, null, null, null);
      AD_PINSTANCE_PARA_INSERT(v_pinstance_id, '60', 'M_Warehouse_ID', cur_not_allocated_stock.m_warehouse_id, null, null, null, null, null);
      AD_PINSTANCE_PARA_INSERT(v_pinstance_id, '70', 'M_Locator_ID', cur_not_allocated_stock.m_locator_id, null, null, null, null, null);
      AD_PINSTANCE_PARA_INSERT(v_pinstance_id, '80', 'M_AttributesetInstance_ID', cur_not_allocated_stock.m_attributesetinstance_id, null, null, null, null, null);
      AD_PINSTANCE_PARA_INSERT(v_pinstance_id, '90', 'Quantity', null, null, cur_not_allocated_stock.quantitytoreserve, null, null, null);
      /*
      * ADD PROPER PROCESS ID!
      */
      AD_PINSTANCE_PARA_INSERT(v_pinstance_id, '100', 'ProcessID', '---', null, null, null, null, null);
  
      IF (cur_not_allocated_stock.c_orderline_id IS NOT NULL) THEN
        SELECT m_warehouse_rule_id INTO v_warehouse_rule_id
        FROM c_orderline
        WHERE c_orderline_id = cur_not_allocated_stock.c_orderline_id;
        AD_PINSTANCE_PARA_INSERT(v_pinstance_id, '110', 'M_Warehouse_Rule_ID', v_warehouse_rule_id, null, null, null, null, null);
      END IF;
  
      M_GET_STOCK(v_pinstance_ID, 'N');
      -- Check result
      SELECT result, errormsg
        INTO v_pinstance_result, v_pinstance_msg
      FROM ad_pinstance
      WHERE ad_pinstance_id = v_pinstance_id;
      IF (v_pinstance_result = 0) THEN
        -- Error on m_get_stock
        RAISE_APPLICATION_ERROR(-20000, v_pinstance_msg);
      END IF;
      SELECT sum(quantity) INTO v_availablestock
      FROM m_stock_proposed
      WHERE ad_pinstance_id = v_pinstance_id;
    END; -- End Call M_GET_STOCK
    
    IF (v_availablestock >= v_qtytorelease) THEN
      M_RESERVE_STOCK_AUTO(cur_not_allocated_stock.m_reservation_id, p_user_id, v_newreservedqty);

      v_pendingtorelease := v_pendingtorelease - v_qtytorelease;
      IF (v_pendingtorelease = 0) THEN
        -- Stock completely released from the reservation
        RETURN;
      END IF;
    ELSE
      --Not enough available stock has been able to reallocate using new stock, undo reallocation.
      UPDATE m_reservation_stock
      SET releasedqty = releasedqty - v_qtytorelease,
          quantity = quantity - v_qtytorelease,
          updated = now(),
          updatedby = p_user_id
      WHERE m_reservation_stock_id = v_res_stock_id;
      v_this_notreserved := v_this_notreserved + v_qtytorelease;
      v_this_noalloc := v_this_noalloc - v_qtytorelease;

      UPDATE m_reservation_stock
      SET quantity = quantity + v_qtytorelease
      WHERE m_reservation_stock_id = cur_not_allocated_stock.m_reservation_stock_id;
    END IF;
  END LOOP;
  -- Delete records with quantity 0 that might be left after a not successfull reallocation attempt.
  DELETE FROM m_reservation_stock
  WHERE m_reservation_id = p_reservation_id
    AND quantity = 0;

  IF (v_pendingtorelease > 0) THEN
    RAISE_APPLICATION_ERROR(-20000, '@CannotConsumeAllStock@');
  END IF;
END M_RESERVATION_CONSUMPTION
]]></body>
    </function>
  </database>