src-db/database/model/triggers/C_ORDERLINE_TRG.xml
author RM packaging bot <staff.rm@openbravo.com>
Thu, 16 Jun 2016 05:35:45 +0000
changeset 29873 73a8cd831ca4
parent 29595 2329370972e3
parent 29854 af0d6a9e780b
child 29874 4a8a100af104
permissions -rw-r--r--
Merge temporary head for 3.0PR16Q2
adrian@94
     1
<?xml version="1.0"?>
adrian@94
     2
  <database name="TRIGGER C_ORDERLINE_TRG">
adrian@94
     3
    <trigger name="C_ORDERLINE_TRG" table="C_ORDERLINE" fires="before" insert="true" update="true" delete="true" foreach="row">
gorkaion@239
     4
      <body><![CDATA[
asier@799
     5
/*************************************************************************
asier@799
     6
  * The contents of this file are subject to the Compiere Public
asier@799
     7
  * License 1.1 ("License"); You may not use this file except in
asier@799
     8
  * compliance with the License. You may obtain a copy of the License in
asier@799
     9
  * the legal folder of your Openbravo installation.
asier@799
    10
  * Software distributed under the License is distributed on an
asier@799
    11
  * "AS IS" basis, WITHOUT WARRANTY OF ANY KIND, either express or
asier@799
    12
  * implied. See the License for the specific language governing rights
asier@799
    13
  * and limitations under the License.
asier@799
    14
  * The Original Code is  Compiere  ERP &  Business Solution
asier@799
    15
  * The Initial Developer of the Original Code is Jorg Janke and ComPiere, Inc.
asier@799
    16
  * Portions created by Jorg Janke are Copyright (C) 1999-2001 Jorg Janke,
asier@799
    17
  * parts created by ComPiere are Copyright (C) ComPiere, Inc.;
asier@799
    18
  * All Rights Reserved.
ggi@6701
    19
  * Contributor(s): Openbravo SLU
aaron@28652
    20
  * Contributions are Copyright (C) 2001-2015 Openbravo, S.L.U.
asier@799
    21
  *
asier@799
    22
  * Specifically, this derivative work is based upon the following Compiere
asier@799
    23
  * file and version.
asier@799
    24
  *************************************************************************/
adrian@170
    25
adrian@94
    26
  v_Prec   NUMBER;
adrianromero@27256
    27
  v_price_prec NUMBER;
juanpablo@1605
    28
  v_ID   VARCHAR2(32);
juanpablo@1605
    29
  v_UOM_ID    VARCHAR2(32);
gorkaion@1240
    30
  v_IsSOTrx CHAR(1);
gorkaion@1240
    31
  v_Count NUMBER;
eduardo@26993
    32
  v_CountRelations NUMBER;
gorkaion@18703
    33
  v_reservation_id    VARCHAR2(32);
gorkaion@18703
    34
  v_prereservedqty    NUMBER;
aaron@28652
    35
  v_IsCashVAT_Tax C_Tax.IsCashVAT%TYPE;
aaron@28652
    36
  v_IsCashVAT_Order C_Order.IsCashVAT%TYPE;
adrianromero@27256
    37
  v_istaxincluded CHAR(1);
adrianromero@27256
    38
  v_PriceActual NUMBER;
adrianromero@27256
    39
  
adrianromero@27256
    40
  v_Warehouse_ID VARCHAR2(32);
adrianromero@27256
    41
  v_BPartner_Location_ID VARCHAR2(32);
adrianromero@27256
    42
  v_Project_ID VARCHAR2(32);  
adrianromero@27256
    43
  v_AsBOM CHAR(1);  
adrianromero@27256
    44
  v_TotalRatio NUMBER;
adrianromero@27256
    45
  v_TotalProducts NUMBER;
adrianromero@27256
    46
  
adrianromero@27256
    47
  v_BaseLine NUMBER;
adrianromero@27256
    48
  v_Line NUMBER;
adrianromero@27256
    49
  v_LineAcum NUMBER;   
adrianromero@27256
    50
  v_NetActual NUMBER;
adrianromero@27256
    51
  v_PriceLine NUMBER;
adrianromero@27256
    52
  v_CalcLine NUMBER;
adrianromero@27256
    53
          
adrianromero@27256
    54
  TYPE RECORD IS REF CURSOR;
aaron@28652
    55
  Cur_BOM RECORD;         
adrian@94
    56
BEGIN
asier@2084
    57
    
asier@2084
    58
    IF AD_isTriggerEnabled()='N' THEN RETURN;
asier@2078
    59
    END IF;
asier@2078
    60
asier@2078
    61
adrian@94
    62
IF (UPDATING) THEN
juanpablo@1605
    63
  IF NOT(COALESCE(:old.M_Product_ID,'0') <> COALESCE(:NEW.M_Product_ID,'0')
gorkaion@239
    64
  OR COALESCE(:old.LineNetAmt,0) <> COALESCE(:NEW.LineNetAmt,0)
gorkaion@239
    65
  OR COALESCE(:old.FreightAmt,0) <> COALESCE(:NEW.FreightAmt,0)
gorkaion@239
    66
  OR COALESCE(:old.ChargeAmt,0) <> COALESCE(:NEW.ChargeAmt,0)
juanpablo@1605
    67
  OR COALESCE(:old.C_Tax_ID,'0') <> COALESCE(:NEW.C_Tax_ID,'0')
asier@4460
    68
  OR COALESCE(:old.C_Uom_ID,'0') <> COALESCE(:NEW.C_Uom_ID,'0')
asier@4460
    69
  OR COALESCE(:old.qtyOrdered,0) <> COALESCE(:NEW.qtyOrdered,0)
adrianromero@27256
    70
  OR COALESCE(:old.PriceActual,0) <> COALESCE(:NEW.PriceActual,0)
adrianromero@27256
    71
  OR COALESCE(:old.gross_unit_price,0) <> COALESCE(:NEW.gross_unit_price,0)
adrianromero@27256
    72
  OR COALESCE(:old.line_gross_amount,0) <> COALESCE(:NEW.line_gross_amount,0))
adrian@94
    73
 THEN
adrian@94
    74
  RETURN;
adrian@94
    75
  END IF;
adrian@94
    76
 END IF;
adrian@94
    77
 /**
adrian@94
    78
  * Check Product changes = not possible when reservation, invoice or delivery exists
adrian@94
    79
  */
adrian@94
    80
 IF (DELETING) THEN
victor@3593
    81
  IF (:old.QtyReserved <> 0 AND :old.C_ORDER_DISCOUNT_ID IS NULL) THEN
naiara@16390
    82
   RAISE_APPLICATION_ERROR(-20000, '@20200@' || ' ' ||:old.QtyReserved);
gorkaion@239
    83
  ELSIF (:old.QtyDelivered <> 0) THEN
naiara@16390
    84
   RAISE_APPLICATION_ERROR(-20000, '@20201@' || ' ' || :old.QtyDelivered);
gorkaion@239
    85
  ELSIF (:old.QtyInvoiced <> 0) THEN
naiara@16390
    86
   RAISE_APPLICATION_ERROR(-20000, '@20202@' || ' ' || :old.QtyInvoiced);
adrian@94
    87
  END IF;
gorkaion@18703
    88
  -- Check if reservation exists to delete it first.
gorkaion@18703
    89
  SELECT issotrx INTO v_IsSOTrx
gorkaion@18703
    90
  FROM c_order
gorkaion@18703
    91
  WHERE c_order_id = :old.c_order_id;
gorkaion@18703
    92
  IF (v_issotrx = 'Y') THEN
gorkaion@18717
    93
    SELECT count(*) INTO v_count
gorkaion@18717
    94
    FROM m_reservation 
gorkaion@18703
    95
    WHERE c_orderline_id = :OLD.c_orderline_id;
gorkaion@18717
    96
    IF (v_count > 0) THEN
unai@25589
    97
      RAISE_APPLICATION_ERROR(-20000, '@DeleteRelatedReservation@');
gorkaion@18703
    98
    END IF;
gorkaion@18703
    99
  ELSE
gorkaion@18703
   100
    DELETE FROM m_reservation_stock
gorkaion@18703
   101
    WHERE c_orderline_id = :OLD.c_orderline_id;
gorkaion@18703
   102
  END IF;
adrian@94
   103
 ELSIF (UPDATING) THEN
gorkaion@1240
   104
   SELECT issotrx INTO v_IsSOTrx
gorkaion@1240
   105
   FROM c_order
gorkaion@1240
   106
   WHERE c_order_id = :old.c_order_id;
rafa@23455
   107
   SELECT count(*) INTO v_count
rafa@23455
   108
    FROM m_reservation 
rafa@23455
   109
    WHERE c_orderline_id = :OLD.c_orderline_id;
eduardo@27017
   110
gorkaion@239
   111
   IF (:old.M_Product_ID <> :NEW.M_Product_ID) THEN
eduardo@26993
   112
     SELECT COUNT(1) into v_CountRelations FROM DUAL 
eduardo@26993
   113
     WHERE EXISTS (SELECT 1 FROM C_ORDERLINE_SERVICERELATION WHERE C_ORDERLINE_ID = :NEW.C_ORDERLINE_ID);
eduardo@26993
   114
     IF(v_CountRelations <> 0) THEN
eduardo@26993
   115
       RAISE_APPLICATION_ERROR(-20000, '@RelationsExist@');
eduardo@26993
   116
     END IF;
gorkaion@1240
   117
     IF (:old.QtyReserved <> 0) THEN
naiara@16390
   118
       RAISE_APPLICATION_ERROR(-20000, '@20203@' || ' ' || :old.QtyReserved);
gorkaion@1240
   119
     ELSIF (:old.QtyDelivered <> 0) THEN
naiara@16390
   120
       RAISE_APPLICATION_ERROR(-20000, '@20204@' || ' ' || :old.QtyDelivered);
gorkaion@1240
   121
     ELSIF (:old.QtyInvoiced <> 0) THEN
naiara@16390
   122
       RAISE_APPLICATION_ERROR(-20000, '@20205@' || ' ' || :old.QtyInvoiced);
gorkaion@1240
   123
     ELSIF (v_IsSOTrx = 'N') THEN
gorkaion@1240
   124
       SELECT count(*) INTO v_Count
gorkaion@1240
   125
       FROM m_inoutline
gorkaion@1240
   126
       WHERE c_orderline_id = :old.c_orderline_id;
gorkaion@1240
   127
       IF (v_count > 0) THEN
naiara@16390
   128
         RAISE_APPLICATION_ERROR(-20000, '@20206@');
gorkaion@1240
   129
       END IF;
gorkaion@22941
   130
       SELECT count(*) INTO v_count
gorkaion@22941
   131
       FROM m_requisitionorder
gorkaion@22941
   132
       WHERE c_orderline_id = :old.c_orderline_id;
gorkaion@22941
   133
       IF (v_count > 0) THEN
gorkaion@22941
   134
         RAISE_APPLICATION_ERROR(-20000, '@ProductChangeLineInRequisition@');
gorkaion@22941
   135
       END IF;
rafa@23455
   136
     -- Looks for a draft reservation for the order line and change its product
rafa@23455
   137
     ELSIF (v_count > 0) THEN
rafa@23455
   138
       SELECT count(*) INTO v_count
rafa@23455
   139
       FROM m_reservation 
rafa@23455
   140
       WHERE c_orderline_id = :OLD.c_orderline_id
rafa@23455
   141
       AND res_status = 'DR';
rafa@23455
   142
       IF (v_count > 0) THEN
rafa@23455
   143
         SELECT max(m_reservation_id) INTO v_reservation_id
rafa@23455
   144
         FROM m_reservation 
rafa@23455
   145
         WHERE c_orderline_id = :OLD.c_orderline_id
atul@24391
   146
         AND m_product_id = :OLD.m_product_id
atul@24391
   147
         AND res_status = 'DR';
rafa@23455
   148
         DELETE FROM m_reservation_stock
rafa@23455
   149
         WHERE m_reservation_id = v_reservation_id;
rafa@23455
   150
         UPDATE m_reservation
rafa@23455
   151
         SET m_product_id = :NEW.M_Product_ID
rafa@23455
   152
         WHERE m_reservation_id = v_reservation_id;
rafa@23455
   153
       ELSE
rafa@23455
   154
         RAISE_APPLICATION_ERROR(-20000, '@ProductChangeLineInReservation@');
rafa@23455
   155
       END IF;
gorkaion@1240
   156
     END IF;
adrian@94
   157
   END IF;
adrianromero@27256
   158
 ELSIF (INSERTING) THEN
adrianromero@27256
   159
   SELECT issotrx INTO v_IsSOTrx
adrianromero@27256
   160
   FROM c_order
adrianromero@27256
   161
   WHERE c_order_id = :NEW.c_order_id;
adrian@94
   162
 END IF;
adrian@94
   163
adrian@94
   164
 -- Get ID
adrian@94
   165
 IF (UPDATING OR INSERTING) THEN
adrian@94
   166
     IF (:NEW.M_PRODUCT_ID IS NOT NULL) THEN
adrian@94
   167
       SELECT C_UOM_ID INTO v_UOM_ID FROM M_PRODUCT WHERE M_PRODUCT_ID=:NEW.M_PRODUCT_ID;
juanpablo@1605
   168
       IF (COALESCE(v_UOM_ID,'0') <> COALESCE(:NEW.C_UOM_ID,'0')) THEN
naiara@16390
   169
         RAISE_APPLICATION_ERROR(-20000, '@20111@');
adrian@94
   170
       END IF;
adrian@94
   171
     END IF;
adrian@94
   172
  v_ID := :new.C_Order_ID;
adrian@94
   173
 ELSE
adrian@94
   174
  v_ID := :old.C_Order_ID;
adrian@94
   175
 END IF;
adrian@94
   176
adrianromero@27256
   177
 SELECT stdPrecision, m_pricelist.istaxincluded, priceprecision, M_WAREHOUSE_ID, C_BPARTNER_LOCATION_ID, C_PROJECT_ID
adrianromero@27256
   178
   INTO v_prec, v_istaxincluded, v_price_prec, v_Warehouse_ID, v_Bpartner_Location_ID, v_Project_ID
adrianromero@27256
   179
 FROM c_order
adrianromero@27256
   180
        JOIN c_currency ON c_order.c_currency_id = c_currency.c_currency_id
adrianromero@27256
   181
        JOIN m_pricelist ON c_order.m_pricelist_id = m_pricelist.m_pricelist_id
adrianromero@27256
   182
 WHERE C_Order_ID = v_ID;
adrian@94
   183
 /**
adrian@94
   184
  * Round Base
adrian@94
   185
  */
adrian@94
   186
 IF (INSERTING OR UPDATING) THEN
adrianromero@27256
   187
  IF (v_istaxincluded = 'Y') THEN
adrianromero@27256
   188
    -- If tax included taxes recalculate net price
adrianromero@27256
   189
    :new.line_gross_amount := ROUND(:new.gross_unit_price * :new.qtyordered, v_prec);
adrianromero@27256
   190
    
adrianromero@27256
   191
    
adrianromero@27256
   192
    
adrianromero@27256
   193
    SELECT tc.ASBOM INTO v_AsBOM FROM C_TAXCATEGORY tc, C_tax t WHERE tc.C_TAXCATEGORY_ID = t.C_TAXCATEGORY_ID AND t.C_TAX_ID = :new.C_Tax_ID;
adrianromero@27256
   194
    IF (v_AsBOM = 'Y') THEN
adrianromero@27256
   195
      -- BOM taxes
adrianromero@27256
   196
      -- Calculate the base for ratios.
adrianromero@27256
   197
      v_BaseLine := :new.line_gross_amount;
adrianromero@27256
   198
      -- Calculate total ratio and number of products
adrianromero@27256
   199
      v_TotalRatio := 0;
adrianromero@27256
   200
      v_TotalProducts := 0;      
adrianromero@27256
   201
      FOR Cur_BOM IN (
adrianromero@27256
   202
        SELECT C_GETTAX(m_productbom_id, :new.UPDATED, :new.AD_Org_ID, v_Warehouse_ID, v_Bpartner_Location_ID, v_Bpartner_Location_ID, v_Project_ID, v_IsSOTRX) AS TAX,
adrianromero@27256
   203
        SUM(ROUND(BOMQTY * BOMPRICE, v_Prec)) AS RATIO FROM m_product_bom WHERE m_product_id = :NEW.M_PRODUCT_ID
adrianromero@27256
   204
        GROUP BY C_GETTAX(m_productbom_id, :new.UPDATED, :new.AD_Org_ID, v_Warehouse_ID, v_Bpartner_Location_ID, v_Bpartner_Location_ID, v_Project_ID, v_IsSOTRX)
adrianromero@27256
   205
        ORDER BY RATIO ASC )
adrianromero@27256
   206
      LOOP
adrianromero@27256
   207
        v_TotalRatio := v_TotalRatio + Cur_BOM.RATIO;
adrianromero@27256
   208
        v_TotalProducts := v_TotalProducts + 1;
adrianromero@27256
   209
      END LOOP;
adrianromero@27256
   210
      
adrianromero@27256
   211
      -- Calculate taxes based on BOM of products  
adrianromero@27256
   212
      v_LineAcum := 0;
adrianromero@27256
   213
      v_NetActual := 0;
adrianromero@27256
   214
      
adrianromero@27256
   215
      FOR Cur_BOM IN (
adrianromero@27256
   216
        SELECT C_GETTAX(m_productbom_id, :new.UPDATED, :new.AD_Org_ID, v_Warehouse_ID, v_Bpartner_Location_ID, v_Bpartner_Location_ID, v_Project_ID, v_IsSOTRX) AS TAX,
adrianromero@27256
   217
        SUM(ROUND(BOMQTY * BOMPRICE, v_Prec)) AS RATIO FROM m_product_bom WHERE m_product_id = :NEW.M_PRODUCT_ID
adrianromero@27256
   218
        GROUP BY C_GETTAX(m_productbom_id, :new.UPDATED, :new.AD_Org_ID, v_Warehouse_ID, v_Bpartner_Location_ID, v_Bpartner_Location_ID, v_Project_ID, v_IsSOTRX)
adrianromero@27256
   219
        ORDER BY RATIO ASC)
adrianromero@27256
   220
      LOOP
adrianromero@27256
   221
       v_TotalProducts := v_TotalProducts - 1;
adrianromero@27256
   222
        IF (v_TotalProducts > 0) THEN
adrianromero@27256
   223
          v_Line := ROUND(v_BaseLine * Cur_BOM.RATIO / v_TotalRatio , v_Prec);
adrianromero@27256
   224
          v_LineAcum := v_LineAcum + v_Line;
adrianromero@27256
   225
        ELSE -- The last willaccummulate rounding
adrianromero@27256
   226
          v_Line := v_BaseLine - v_LineAcum;
adrianromero@27256
   227
        END IF;
adrianromero@27256
   228
adrianromero@27256
   229
        v_PriceLine := C_GET_NET_PRICE_FROM_GROSS(Cur_BOM.TAX, v_Line, v_Line, v_price_prec, :new.qtyordered);     
adrianromero@27256
   230
        v_CalcLine := ROUND(:new.qtyordered * v_PriceLine, v_Prec); -- In price including taxes the net and net alternate are equals.
adrianromero@27256
   231
        v_NetActual := v_NetActual + v_CalcLine; -- Acum the net
adrianromero@27256
   232
      END LOOP;    
adrianromero@27256
   233
      v_PriceActual := ROUND(v_NetActual / :new.qtyordered, v_price_prec);     
adrianromero@27256
   234
    ELSE
adrianromero@27256
   235
      -- Regular taxes
alvaro@28398
   236
      v_PriceActual := C_GET_NET_PRICE_FROM_GROSS(:new.c_tax_id, :new.gross_unit_price * :new.qtyordered, :new.taxbaseamt, v_price_prec, :new.qtyordered);
adrianromero@27256
   237
      v_NetActual := ROUND(:new.QtyOrdered * v_PriceActual, v_Prec);
adrianromero@27256
   238
    END IF;      
adrianromero@27256
   239
    
adrianromero@27256
   240
    :NEW.pricestd := v_priceactual;
adrianromero@27256
   241
    :NEW.pricelist := v_priceactual;
adrianromero@27256
   242
    :NEW.pricelimit := v_priceactual;
adrianromero@27256
   243
    :NEW.priceactual := v_priceactual;
adrianromero@27256
   244
    :new.taxbaseamt := v_NetActual;
adrianromero@27256
   245
    :new.LineNetAmt := v_NetActual;
adrianromero@27256
   246
  ELSE
adrianromero@27256
   247
    -- Price including taxes = 'N'
adrianromero@27256
   248
    -- Modified by I.Ciordia. Sometimes js fails calculting lineNet
adrianromero@27256
   249
    :new.LineNetAmt := ROUND(:new.QtyOrdered*:new.PriceActual, v_Prec);-- Modified by I.Ciordia  
adrianromero@27256
   250
  END IF;
adrianromero@27256
   251
  
adrian@94
   252
  :new.FreightAmt := ROUND(:new.FreightAmt, v_Prec);
adrianromero@27256
   253
  :new.ChargeAmt := ROUND(:new.ChargeAmt, v_Prec);  
adrian@94
   254
 END IF;
adrian@94
   255
aaron@28652
   256
 -- Update C_Order.IsCashVAT flag from the line tax rate.
aaron@28652
   257
 -- We do it this way to force any process that creates Orders to properly set the C_Order.IsCashVAT
aaron@28652
   258
 -- If a user manually changes the tax rate when entering a line, the order's header IsCash VAT may change
aaron@28652
   259
 IF (INSERTING OR UPDATING) THEN
aaron@28652
   260
  IF (:NEW.C_TAX_ID IS NOT NULL) THEN  
aaron@28652
   261
   SELECT CASE WHEN COUNT(*) > 0 THEN 'Y' ELSE 'N' END
aaron@28652
   262
   INTO v_IsCashVAT_Tax
aaron@28652
   263
   FROM dual
aaron@28652
   264
   WHERE EXISTS (
aaron@28652
   265
        select 1
aaron@28652
   266
        from c_tax t
aaron@28652
   267
        where C_TAX_ISMEMBER(:NEW.C_Tax_ID, t.c_tax_id) = 1
aaron@28652
   268
        and t.isCashVAT = 'Y'
aaron@28652
   269
        and t.rate <> 0
aaron@28652
   270
        and t.isSummary = 'N'
aaron@28652
   271
                 );
aaron@28652
   272
aaron@28652
   273
   SELECT COALESCE(IsCashVAT, 'N')
aaron@28652
   274
   INTO v_IsCashVAT_Order
aaron@28652
   275
   FROM C_Order
aaron@28652
   276
   WHERE C_Order_ID=:NEW.C_Order_ID;
aaron@28652
   277
aaron@28652
   278
   IF (v_IsCashVAT_Tax <> v_IsCashVAT_Order) THEN
aaron@28652
   279
     UPDATE C_Order
aaron@28652
   280
     SET IsCashVAT = v_IsCashVAT_Tax
aaron@28652
   281
     WHERE C_Order_ID=:NEW.C_Order_ID;
aaron@28652
   282
   END IF;
aaron@28652
   283
  END IF;
aaron@28652
   284
 END IF;
aaron@28652
   285
antonio@735
   286
END C_ORDERLINE_TRG
gorkaion@239
   287
]]></body>
adrian@94
   288
    </trigger>
adrian@94
   289
  </database>