src-db/database/model/triggers/C_INVOICELINE_TRG2.xml
author Harikrishnan Raja <harikrishnan.raja@openbravo.com>
Mon, 17 May 2010 14:59:02 +0530
changeset 7382 a768ad8bc4d8
parent 6701 690d2af86089
child 7567 0569c1e9f6ee
permissions -rw-r--r--
Fixes Issue 13190 Before in the trigger the total net amount is not calculated during the deletion of the trigger.
adrian@94
     1
<?xml version="1.0"?>
adrian@94
     2
  <database name="TRIGGER C_INVOICELINE_TRG2">
adrian@94
     3
    <trigger name="C_INVOICELINE_TRG2" table="C_INVOICELINE" fires="after" 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 Openbravo  Public  License
asier@799
     7
* Version  1.0  (the  "License"),  being   the  Mozilla   Public  License
asier@799
     8
* Version 1.1  with a permitted attribution clause; you may not  use this
asier@799
     9
* file except in compliance with the License. You  may  obtain  a copy of
asier@799
    10
* the License at http://www.openbravo.com/legal/license.html
asier@799
    11
* Software distributed under the License  is  distributed  on  an "AS IS"
asier@799
    12
* basis, WITHOUT WARRANTY OF ANY KIND, either express or implied. See the
asier@799
    13
* License for the specific  language  governing  rights  and  limitations
asier@799
    14
* under the License.
asier@799
    15
* The Original Code is Openbravo ERP.
ggi@6701
    16
* The Initial Developer of the Original Code is Openbravo SLU
ggi@6701
    17
* All portions are Copyright (C) 2001-2008 Openbravo SLU
asier@799
    18
* All Rights Reserved.
asier@799
    19
* Contributor(s):  ______________________________________.
asier@799
    20
************************************************************************/
gorkaion@239
    21
adrian@170
    22
adrian@94
    23
adrian@94
    24
adrian@94
    25
adrian@94
    26
   TYPE RECORD IS REF CURSOR;
adrian@94
    27
   Cur_Offer RECORD;
adrian@94
    28
juanpablo@1605
    29
  v_InvoiceLine_Offer_ID VARCHAR2(32);
antonio@735
    30
  v_lineno NUMBER:=0;
adrian@94
    31
  v_Price NUMBER;
adrian@94
    32
  v_PriceNew NUMBER;
adrian@94
    33
  v_Amt NUMBER;
juanpablo@1605
    34
  v_BPartner_ID VARCHAR2(32);
juanpablo@1605
    35
  v_Order_ID VARCHAR2(32);
adrian@94
    36
  v_Insert BOOLEAN :=FALSE;
adrian@94
    37
  v_DateInvoiced DATE;
adrian@94
    38
  v_Precision NUMBER;
juanpablo@1605
    39
  v_PriceList_ID VARCHAR2(32);
eduardo@6017
    40
  v_Processed C_ORDER.PROCESSED%TYPE;
eduardo@6017
    41
  v_ID VARCHAR2(32);
eduardo@6017
    42
  v_oldLine NUMBER;
eduardo@6017
    43
  v_newLineNetAmt NUMBER;
eduardo@6017
    44
  v_newLineAlternate NUMBER;
eduardo@6017
    45
  v_taxAmt NUMBER;
eduardo@6017
    46
  v_Prec C_CURRENCY.STDPRECISION%TYPE;
eduardo@6017
    47
  v_BaseAmount C_TAX.BASEAMOUNT%TYPE;
asier@2084
    48
    
adrian@94
    49
BEGIN
asier@2084
    50
    
asier@2084
    51
    IF AD_isTriggerEnabled()='N' THEN RETURN;
asier@2078
    52
    END IF;
asier@2078
    53
asier@2078
    54
adrian@94
    55
-- This trigger is used for calculate the applied offers f0r the invoice
adrian@94
    56
eduardo@6017
    57
IF (DELETING) THEN
eduardo@6017
    58
  v_ID:=:OLD.C_INVOICE_ID;
eduardo@6017
    59
ELSE
eduardo@6017
    60
  v_ID:=:NEW.C_INVOICE_ID;
eduardo@6017
    61
END IF;
adrian@94
    62
adrian@94
    63
 IF UPDATING THEN
juanpablo@1605
    64
  IF (    (COALESCE(:NEW.M_Product_ID,'0') != COALESCE(:OLD.M_Product_ID,'0'))
adrian@94
    65
    OR (COALESCE(:NEW.PriceActual,0) != COALESCE(:OLD.PriceActual,0))
adrian@94
    66
    OR (COALESCE(:NEW.QtyInvoiced,0) != COALESCE(:OLD.QtyInvoiced,0))) THEN
adrian@94
    67
  DELETE FROM C_INVOICELINE_OFFER
adrian@94
    68
   WHERE C_InvoiceLine_ID = :NEW.C_InvoiceLine_ID;
adrian@94
    69
   v_Insert := TRUE;
adrian@94
    70
   END IF;
adrian@94
    71
 END IF;
adrian@94
    72
adrian@94
    73
 IF INSERTING OR v_Insert THEN
adrian@94
    74
   SELECT C_BPartner_ID, dateInvoiced, priceprecision, M_PriceList_ID
adrian@94
    75
    INTO v_BPartner_ID, v_DateInvoiced, v_Precision, v_PriceList_ID
adrian@94
    76
     FROM C_INVOICE i,
adrian@94
    77
          C_CURRENCY c
adrian@94
    78
   WHERE C_Invoice_ID = :NEW.C_Invoice_ID
adrian@94
    79
     AND i.C_Currency_ID = c.C_Currency_ID;
adrian@94
    80
adrian@94
    81
adrian@94
    82
   --Get the new "std" price from the Actual price (if actual price is the std price they will be equal)
adrian@94
    83
   v_Price := :NEW.PriceActual;
adrian@94
    84
    FOR Cur_Offer IN (SELECT M_OFFER_ID
adrian@94
    85
         FROM M_OFFER
gorkaion@280
    86
         WHERE v_DateInvoiced BETWEEN DATEFROM AND COALESCE(DATETO,TO_DATE('31-12-9999','DD-MM-YYYY'))
adrian@94
    87
   AND IsActive = 'Y'
gorkaion@239
    88
   AND (:NEW.QtyInvoiced >= COALESCE(Qty_From,0) OR Qty_From IS NULL)
gorkaion@239
    89
   AND (:NEW.QtyInvoiced <= COALESCE(Qty_To,0) OR Qty_To IS NULL)
adrian@94
    90
   AND ((PRICELIST_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM M_OFFER_PRICELIST
adrian@94
    91
           WHERE M_OFFER_ID=M_OFFER.M_OFFER_ID
adrian@94
    92
           AND M_PRICELIST_ID = v_PriceList_ID))
adrian@94
    93
     OR (PRICELIST_SELECTION='N' AND EXISTS(SELECT 1 FROM M_OFFER_PRICELIST
adrian@94
    94
            WHERE M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
    95
            AND M_PRICELIST_ID = v_PriceList_ID)))
adrian@94
    96
         AND ((BPARTNER_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM M_OFFER_BPARTNER
adrian@94
    97
           WHERE M_OFFER_ID=M_OFFER.M_OFFER_ID
adrian@94
    98
           AND C_BPARTNER_ID = v_BPartner_ID))
adrian@94
    99
         OR (BPARTNER_SELECTION='N' AND EXISTS(SELECT 1 FROM M_OFFER_BPARTNER
adrian@94
   100
            WHERE M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
   101
            AND C_BPARTNER_ID = v_BPartner_ID)))
adrian@94
   102
         AND ((BP_GROUP_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM C_BPARTNER B, M_OFFER_BP_GROUP OB
adrian@94
   103
           WHERE OB.M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
   104
           AND B.C_BPARTNER_ID = v_BPartner_ID
adrian@94
   105
           AND OB.C_BP_GROUP_ID = B.C_BP_GROUP_ID))
adrian@94
   106
         OR (BP_GROUP_SELECTION='N' AND EXISTS (SELECT 1 FROM C_BPARTNER B, M_OFFER_BP_GROUP OB
adrian@94
   107
           WHERE OB.M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
   108
           AND B.C_BPARTNER_ID = v_BPartner_ID
adrian@94
   109
           AND OB.C_BP_GROUP_ID = B.C_BP_GROUP_ID)))
adrian@94
   110
         AND ((PRODUCT_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM M_OFFER_PRODUCT
adrian@94
   111
           WHERE M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
   112
           AND M_PRODUCT_ID = :NEW.M_PRODUCT_ID))
adrian@94
   113
         OR (PRODUCT_SELECTION='N' AND EXISTS (SELECT 1 FROM M_OFFER_PRODUCT
adrian@94
   114
            WHERE M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
   115
            AND M_PRODUCT_ID = :NEW.M_PRODUCT_ID)))
adrian@94
   116
         AND ((PROD_CAT_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM M_PRODUCT P, M_OFFER_PROD_CAT OP
adrian@94
   117
           WHERE OP.M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
   118
           AND P.M_PRODUCT_ID = :NEW.M_PRODUCT_ID
adrian@94
   119
           AND OP.M_PRODUCT_CATEGORY_ID = P.M_PRODUCT_CATEGORY_ID))
adrian@94
   120
         OR (PROD_CAT_SELECTION='N' AND EXISTS (SELECT 1 FROM M_PRODUCT P, M_OFFER_PROD_CAT OP
adrian@94
   121
           WHERE OP.M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
   122
           AND P.M_PRODUCT_ID = :NEW.M_PRODUCT_ID
adrian@94
   123
           AND OP.M_PRODUCT_CATEGORY_ID = P.M_PRODUCT_CATEGORY_ID)))
adrian@94
   124
         ORDER BY PRIORITY DESC, M_OFFER_ID) LOOP
adrian@94
   125
    v_Price := M_Get_Offer_Std_Price(Cur_Offer.M_Offer_ID, v_Price);
adrian@94
   126
   END LOOP;
adrian@94
   127
adrian@94
   128
   FOR Cur_Offer IN (SELECT M_OFFER_ID
adrian@94
   129
    FROM M_OFFER
gorkaion@280
   130
    WHERE v_DateInvoiced BETWEEN DATEFROM AND COALESCE(DATETO,TO_DATE('31-12-9999','DD-MM-YYYY'))
adrian@94
   131
 AND IsActive = 'Y'
gorkaion@239
   132
 AND (:NEW.QtyInvoiced >= COALESCE(Qty_From,0) OR Qty_From IS NULL)
gorkaion@239
   133
   AND (:NEW.QtyInvoiced <= COALESCE(Qty_To,0) OR Qty_To IS NULL)
adrian@94
   134
   AND ((PRICELIST_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM M_OFFER_PRICELIST
adrian@94
   135
           WHERE M_OFFER_ID=M_OFFER.M_OFFER_ID
adrian@94
   136
           AND M_PRICELIST_ID = v_PriceList_ID))
adrian@94
   137
     OR (PRICELIST_SELECTION='N' AND EXISTS(SELECT 1 FROM M_OFFER_PRICELIST
adrian@94
   138
            WHERE M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
   139
            AND M_PRICELIST_ID = v_PriceList_ID)))
adrian@94
   140
    AND ((BPARTNER_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM M_OFFER_BPARTNER
adrian@94
   141
      WHERE M_OFFER_ID=M_OFFER.M_OFFER_ID
adrian@94
   142
      AND C_BPARTNER_ID = v_BPartner_ID))
adrian@94
   143
    OR (BPARTNER_SELECTION='N' AND EXISTS(SELECT 1 FROM M_OFFER_BPARTNER
adrian@94
   144
       WHERE M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
   145
       AND C_BPARTNER_ID = v_BPartner_ID)))
adrian@94
   146
    AND ((BP_GROUP_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM C_BPARTNER B, M_OFFER_BP_GROUP OB
adrian@94
   147
      WHERE OB.M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
   148
      AND B.C_BPARTNER_ID = v_BPartner_ID
adrian@94
   149
      AND OB.C_BP_GROUP_ID = B.C_BP_GROUP_ID))
adrian@94
   150
    OR (BP_GROUP_SELECTION='N' AND EXISTS (SELECT 1 FROM C_BPARTNER B, M_OFFER_BP_GROUP OB
adrian@94
   151
      WHERE OB.M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
   152
      AND B.C_BPARTNER_ID = v_BPartner_ID
adrian@94
   153
      AND OB.C_BP_GROUP_ID = B.C_BP_GROUP_ID)))
adrian@94
   154
    AND ((PRODUCT_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM M_OFFER_PRODUCT
adrian@94
   155
      WHERE M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
   156
      AND M_PRODUCT_ID = :NEW.M_PRODUCT_ID))
adrian@94
   157
    OR (PRODUCT_SELECTION='N' AND EXISTS (SELECT 1 FROM M_OFFER_PRODUCT
adrian@94
   158
       WHERE M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
   159
       AND M_PRODUCT_ID = :NEW.M_PRODUCT_ID)))
adrian@94
   160
    AND ((PROD_CAT_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM M_PRODUCT P, M_OFFER_PROD_CAT OP
adrian@94
   161
      WHERE OP.M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
   162
      AND P.M_PRODUCT_ID = :NEW.M_PRODUCT_ID
adrian@94
   163
      AND OP.M_PRODUCT_CATEGORY_ID = P.M_PRODUCT_CATEGORY_ID))
adrian@94
   164
    OR (PROD_CAT_SELECTION='N' AND EXISTS (SELECT 1 FROM M_PRODUCT P, M_OFFER_PROD_CAT OP
adrian@94
   165
      WHERE OP.M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
   166
      AND P.M_PRODUCT_ID = :NEW.M_PRODUCT_ID
adrian@94
   167
      AND OP.M_PRODUCT_CATEGORY_ID = P.M_PRODUCT_CATEGORY_ID)))
adrian@94
   168
    ORDER BY PRIORITY, M_OFFER_ID DESC) LOOP
adrian@94
   169
   Ad_Sequence_Next('C_InvoiceLine_Offer', :NEW.AD_Client_ID, v_InvoiceLine_Offer_ID);
adrian@94
   170
   v_lineno := v_lineno + 10;
adrian@94
   171
   v_PriceNew := M_Get_Offer_Price(Cur_Offer.M_Offer_ID, v_Price);
adrian@94
   172
   v_Amt := v_Price - v_PriceNew;
adrian@94
   173
adrian@94
   174
   INSERT INTO C_INVOICELINE_OFFER
adrian@94
   175
       (C_INVOICELINE_OFFER_ID, AD_CLIENT_ID, AD_ORG_ID, ISACTIVE,
adrian@94
   176
      CREATED, CREATEDBY, UPDATED, UPDATEDBY,
adrian@94
   177
      C_INVOICELINE_ID, LINE, M_OFFER_ID, PRICEOFFER, AMTOFFER)
adrian@94
   178
   VALUES
adrian@94
   179
       (v_InvoiceLine_Offer_ID, :NEW.AD_Client_ID, :NEW.AD_Org_ID, :NEW.IsActive,
antonio@735
   180
      now(),:NEW.CreatedBy, now(),:NEW.UpdatedBy,
adrian@94
   181
     :NEW.C_InvoiceLine_ID, v_lineno, Cur_Offer.M_Offer_Id, ROUND(v_Price,v_Precision), ROUND(v_Amt, v_Precision));
adrian@94
   182
    v_Price := v_PriceNew;
adrian@94
   183
  END LOOP;
adrian@94
   184
 END IF;
adrian@94
   185
eduardo@6017
   186
  /**************************************************************************
eduardo@6017
   187
   * Calculate Tax, etc.
eduardo@6017
   188
   */
eduardo@6017
   189
 SELECT processed, stdPrecision
eduardo@6017
   190
   INTO v_Processed, v_Prec
eduardo@6017
   191
 FROM C_Invoice, C_Currency
eduardo@6017
   192
 WHERE C_Invoice.C_Currency_ID = C_Currency.C_Currency_ID
eduardo@6017
   193
 AND C_Invoice_ID=v_ID;
eduardo@6017
   194
 v_oldLine:=0;
eduardo@6017
   195
 v_newLineNetAmt:=0;
eduardo@6017
   196
 IF(v_Processed='N') THEN
eduardo@6017
   197
  -- Calculate taxes
harikrishnan@7382
   198
  IF(UPDATING OR DELETING) THEN
eduardo@6017
   199
  v_oldLine:= COALESCE(:old.LineNetAmt,0);
eduardo@6017
   200
  END IF;  
eduardo@6017
   201
  IF (INSERTING OR UPDATING) THEN
eduardo@6017
   202
   DELETE FROM C_INVOICELINETAX WHERE C_INVOICELINE_ID = :new.C_InvoiceLine_ID;
eduardo@6017
   203
   v_newLineNetAmt := COALESCE(:new.LineNetAmt,0);
eduardo@6017
   204
   v_newLineAlternate := COALESCE(:new.TaxBaseAmt,0);
eduardo@6054
   205
   IF(:new.C_Tax_ID IS NOT NULL) THEN
eduardo@6054
   206
     SELECT BaseAmount INTO v_BaseAmount
eduardo@6054
   207
     FROM C_TAX
eduardo@6054
   208
     WHERE C_TAX_ID = :new.C_Tax_ID;
eduardo@6054
   209
     C_INVOICELINETAX_INSERT(:new.AD_Org_ID, :new.C_Invoice_ID, :new.C_InvoiceLine_ID, :new.UpdatedBy, :new.C_Tax_ID, :new.C_Tax_ID, v_newLineNetAmt, v_newLineAlternate, v_Prec);
eduardo@6054
   210
   END IF;
eduardo@6017
   211
  -- Get Total Tax Amt
eduardo@6017
   212
   SELECT SUM(TaxAmt)
eduardo@6017
   213
     INTO v_taxAmt
eduardo@6017
   214
   FROM C_InvoiceTax
eduardo@6017
   215
   WHERE C_Invoice_ID=:new.C_Invoice_ID;
eduardo@6017
   216
  -- DBMS_OUTPUT.PUT_LINE('TaxAmt = ' || v_taxAmt);
eduardo@6017
   217
   -- Update Header
eduardo@6017
   218
   UPDATE C_Invoice
eduardo@6017
   219
     SET TotalLines = TotalLines - v_oldLine + v_newLineNetAmt,
eduardo@6017
   220
     GrandTotal = TotalLines - v_oldLine + v_newLineNetAmt + COALESCE(v_taxAmt, 0)
eduardo@6017
   221
   --  Updated = SysDate -- Don't update as otherwise it does not save changes
eduardo@6017
   222
   WHERE C_Invoice_ID = :new.C_Invoice_ID;
eduardo@6017
   223
  ELSE -- DELETING
eduardo@6017
   224
   SELECT SUM(TaxAmt)
eduardo@6017
   225
     INTO v_taxAmt
eduardo@6017
   226
   FROM C_InvoiceTax
eduardo@6017
   227
   WHERE C_Invoice_ID=:old.C_Invoice_ID;
eduardo@6017
   228
  -- DBMS_OUTPUT.PUT_LINE('TaxAmt = ' || v_taxAmt);
eduardo@6017
   229
   -- Update Header
eduardo@6017
   230
   UPDATE C_Invoice
eduardo@6017
   231
     SET TotalLines = TotalLines - v_oldLine + v_newLineNetAmt,
eduardo@6017
   232
     GrandTotal = TotalLines - v_oldLine + v_newLineNetAmt + COALESCE(v_taxAmt, 0)
eduardo@6017
   233
   --  Updated = SysDate -- Don't update as otherwise it does not save changes
eduardo@6017
   234
   WHERE C_Invoice_ID=:old.C_Invoice_ID;
eduardo@6017
   235
  END IF;
eduardo@6017
   236
 END IF;
eduardo@6017
   237
eduardo@6017
   238
antonio@735
   239
END C_INVOICELINE_TRG2
gorkaion@239
   240
]]></body>
adrian@94
   241
    </trigger>
adrian@94
   242
  </database>