src-db/database/model/triggers/M_TRANSACTION_TRG2.xml
author Guillermo Alvarez de Eulate <guillermo.alvarez@openbravo.com>
Tue, 20 Aug 2013 09:33:47 +0200
changeset 20997 55c000c91897
parent 20977 21d0baeb6c99
child 20998 8d3f43817c4f
permissions -rw-r--r--
related to issue 24389: backed out changeset 21d0baeb6c99
gorkaion@18660
     1
<?xml version="1.0"?>
gorkaion@18660
     2
  <database name="TRIGGER M_TRANSACTION_TRG2">
gorkaion@18660
     3
    <trigger name="M_TRANSACTION_TRG2" table="M_TRANSACTION" fires="before" insert="true" update="false" delete="false" foreach="row">
gorkaion@18660
     4
      <body><![CDATA[
gorkaion@18660
     5
gorkaion@18660
     6
/*************************************************************************
gorkaion@18660
     7
* The contents of this file are subject to the Openbravo  Public  License
gorkaion@18660
     8
* Version  1.1  (the  "License"),  being   the  Mozilla   Public  License
gorkaion@18660
     9
* Version 1.1  with a permitted attribution clause; you may not  use this
gorkaion@18660
    10
* file except in compliance with the License. You  may  obtain  a copy of
gorkaion@18660
    11
* the License at http://www.openbravo.com/legal/license.html
gorkaion@18660
    12
* Software distributed under the License  is  distributed  on  an "AS IS"
gorkaion@18660
    13
* basis, WITHOUT WARRANTY OF ANY KIND, either express or implied. See the
gorkaion@18660
    14
* License for the specific  language  governing  rights  and  limitations
gorkaion@18660
    15
* under the License.
gorkaion@18660
    16
* The Original Code is Openbravo ERP.
gorkaion@18660
    17
* The Initial Developer of the Original Code is Openbravo SLU
pandeeswari@20828
    18
* All portions are Copyright (C) 2012-2013 Openbravo SLU
gorkaion@18660
    19
* All Rights Reserved.
gorkaion@18660
    20
* Contributor(s):  ______________________________________.
gorkaion@18660
    21
************************************************************************/
gorkaion@18660
    22
  v_onhand      NUMBER;
gorkaion@18660
    23
  v_reserved    NUMBER;
gorkaion@18668
    24
  v_count       NUMBER;
gorkaion@20941
    25
  v_productname m_product.name%TYPE;
gorkaion@20941
    26
  v_isgeneric   CHAR(1);
pandeeswari@20828
    27
  v_product     VARCHAR(60);
pandeeswari@20828
    28
  v_attr_description    VARCHAR2(255);
pandeeswari@20828
    29
  v_product_value       VARCHAR2(40);
pandeeswari@20828
    30
  v_locator_value       VARCHAR2(40);
pandeeswari@20828
    31
  v_uom_value           VARCHAR2(3);
gorkaion@18660
    32
gorkaion@18660
    33
BEGIN
gorkaion@18660
    34
  IF (AD_isTriggerEnabled() = 'N') THEN RETURN;
gorkaion@18660
    35
  END IF;
gorkaion@18660
    36
gorkaion@18660
    37
  IF (INSERTING) THEN
guillermo@20997
    38
    IF (:NEW.isreservationtriggerdisabled = 'Y') THEN
guillermo@20997
    39
      RETURN NEW;
guillermo@20975
    40
    END IF;
gorkaion@18668
    41
    IF (:NEW.movementqty < 0 AND :NEW.m_product_uom_id IS NULL) THEN
gorkaion@18660
    42
      -- Check reservations. Reserved stock must be released before inserting the transacion.
gorkaion@18668
    43
      SELECT count(1) INTO v_count
gorkaion@18668
    44
      FROM dual
gorkaion@18668
    45
      WHERE EXISTS (SELECT 1
gorkaion@18668
    46
                    FROM m_reservation r
gorkaion@18668
    47
                        JOIN m_reservation_stock rs ON r.m_reservation_id = rs.m_reservation_id
gorkaion@18723
    48
                    WHERE r.res_status NOT IN ('CL', 'DR')
gorkaion@18669
    49
                      AND r.m_product_id = :NEW.m_product_id
gorkaion@18668
    50
                      AND r.c_uom_id = :NEW.c_uom_id
gorkaion@18668
    51
                      AND COALESCE(rs.m_attributesetinstance_id, '0') = :NEW.m_attributesetinstance_id
gorkaion@18668
    52
                      AND rs.m_locator_id = :NEW.m_locator_id);
gorkaion@18723
    53
      IF (v_count > 0) THEN
gorkaion@18668
    54
        SELECT COALESCE(sum(rs.quantity - COALESCE(rs.releasedqty,0)), 0), sd.qtyonhand
gorkaion@18668
    55
          INTO v_reserved, v_onhand
gorkaion@18668
    56
        FROM m_reservation_stock rs
gorkaion@18668
    57
            JOIN m_reservation r ON rs.m_reservation_id = r.m_reservation_id
gorkaion@18668
    58
            JOIN m_storage_detail sd ON r.m_product_id = sd.m_product_id
gorkaion@18668
    59
                                        AND r.c_uom_id = sd.c_uom_id
gorkaion@18668
    60
                                        AND COALESCE(rs.m_attributesetinstance_id, '0') = COALESCE(sd.m_attributesetinstance_id, '0')
gorkaion@18668
    61
                                        AND rs.m_locator_id = sd.m_locator_id
gorkaion@18668
    62
                                        AND sd.m_product_uom_id IS NULL
gorkaion@18723
    63
        WHERE r.res_status NOT IN ('CL', 'DR')
gorkaion@18668
    64
          AND r.m_product_id = :NEW.m_product_id
gorkaion@18668
    65
          AND r.c_uom_id = :NEW.c_uom_id
gorkaion@18668
    66
          AND COALESCE(rs.m_attributesetinstance_id, '0') = :NEW.m_attributesetinstance_id
gorkaion@18668
    67
          AND rs.m_locator_id = :NEW.m_locator_id
gorkaion@18668
    68
        GROUP BY sd.qtyonhand, sd.m_storage_detail_id;
gorkaion@18668
    69
        IF (v_onhand - v_reserved < ABS(:NEW.movementqty)) THEN
pandeeswari@20828
    70
	  SELECT value
pandeeswari@20828
    71
            INTO v_product_value
pandeeswari@20828
    72
          FROM M_Product
pandeeswari@20828
    73
          WHERE M_Product_ID = :NEW.m_product_id;
pandeeswari@20828
    74
pandeeswari@20828
    75
          IF(:NEW.m_attributesetinstance_id IS NOT NULL) THEN
pandeeswari@20828
    76
            SELECT description
pandeeswari@20828
    77
              INTO v_attr_description
pandeeswari@20828
    78
            FROM M_AttributeSetInstance
pandeeswari@20828
    79
            WHERE M_AttributeSetInstance_ID = :NEW.m_attributesetinstance_id;
pandeeswari@20828
    80
          END IF;
pandeeswari@20828
    81
pandeeswari@20828
    82
          SELECT uomsymbol
pandeeswari@20828
    83
            INTO v_uom_value
pandeeswari@20828
    84
          FROM C_Uom
pandeeswari@20828
    85
          WHERE C_Uom_ID = :NEW.c_uom_id;
pandeeswari@20828
    86
pandeeswari@20828
    87
          IF (:NEW.m_locator_id IS NOT NULL) THEN
pandeeswari@20828
    88
            SELECT value
pandeeswari@20828
    89
              INTO v_locator_value
pandeeswari@20828
    90
            FROM M_Locator
pandeeswari@20828
    91
            WHERE M_Locator_ID = :NEW.m_locator_id;
pandeeswari@20828
    92
          END IF;
pandeeswari@20828
    93
          RAISE_APPLICATION_ERROR(-20000, '@CannotTakeOutReservedStock@' || ' @of@' || ' @Product@: ' || v_product_value || ', @AttributeSetInstance@: ' || COALESCE(v_attr_description, '-') || ', @UOM@: ' || v_uom_value || ' @And@'||' @StorageBin@: ' || COALESCE(v_locator_value, '-'));
gorkaion@18668
    94
        END IF;
gorkaion@18660
    95
      END IF;
gorkaion@18660
    96
    END IF;
gorkaion@20941
    97
    IF (:NEW.m_product_id IS NOT NULL) THEN
gorkaion@20941
    98
      SELECT isgeneric, name INTO v_isgeneric, v_productname
gorkaion@20941
    99
      FROM m_product
gorkaion@20941
   100
      WHERE m_product_id = :NEW.m_product_id;
gorkaion@20941
   101
      IF (v_isgeneric = 'Y') THEN
gorkaion@20941
   102
        RAISE_APPLICATION_ERROR(-20000, '@CannotUseGenericProduct@');
gorkaion@20941
   103
      END IF;
gorkaion@20941
   104
    END IF;
gorkaion@18660
   105
  END IF;
gorkaion@18660
   106
END M_TRANSACTION_TRG2
gorkaion@18660
   107
]]></body>
gorkaion@18660
   108
    </trigger>
gorkaion@18660
   109
  </database>