src-db/database/model/triggers/C_INVOICELINE_TRG2.xml
author Mark <markmm82@gmail.com>
Tue, 28 Feb 2017 14:56:32 -0500
changeset 31570 68702618a590
parent 31540 e6fef7749bc4
child 31599 b3ee13f262a4
permissions -rw-r--r--
Related to issue 34993: Logic moved to the complete action

To avoid inconsistents scenarios in this issue, the processing logic included inside
the c_invoiceline_trg2 trigger was removed and included inside the c_invoice_post function.

This way the prepayment amount is always updated when the invoice is completed and
not when it lines are created, updated or deleted.

All other possible scenarios will be covered when the related design defect
https://issues.openbravo.com/view.php?id=35339 be fixed.
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
priya@9072
     7
* Version  1.1  (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
markmm82@31540
    17
* All portions are Copyright (C) 2001-2017 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
eduardo@6017
    24
  v_Processed C_ORDER.PROCESSED%TYPE;
eduardo@6017
    25
  v_ID VARCHAR2(32);
sanjota@31526
    26
  v_oldLine NUMBER;
eduardo@6017
    27
  v_newLineNetAmt NUMBER;
eduardo@6017
    28
  v_newLineAlternate NUMBER;
eduardo@6017
    29
  v_taxAmt NUMBER;
eduardo@6017
    30
  v_Prec C_CURRENCY.STDPRECISION%TYPE;
adrianromero@27136
    31
  v_PricePrec C_CURRENCY.PRICEPRECISION%TYPE;
hari@17336
    32
  v_istaxincluded CHAR(1) ;
hari@17336
    33
  v_oldGrossAmt NUMBER:=0;
hari@17336
    34
  v_newGrossAmt NUMBER:=0;
hari@17336
    35
  v_totallines NUMBER:=0;
hari@17336
    36
  v_grandtotal NUMBER:=0;
unai@26214
    37
  v_oldLineAlternate NUMBER;
adrianromero@27136
    38
  v_create CHAR(1):='Y';  
adrianromero@27136
    39
  
adrianromero@27136
    40
  v_Warehouse_ID VARCHAR2(32);
adrianromero@27136
    41
  v_BPartner_Location_ID VARCHAR2(32);
adrianromero@27136
    42
  v_Project_ID VARCHAR2(32);
adrianromero@27136
    43
  v_IsSOTRX CHAR(1);
adrianromero@27136
    44
  v_AsBOM CHAR(1);  
adrianromero@27136
    45
  v_TotalRatio NUMBER;
adrianromero@27136
    46
  v_TotalProducts NUMBER;
adrianromero@27136
    47
  
adrianromero@27136
    48
  v_BaseLine NUMBER;
adrianromero@27136
    49
  v_Line NUMBER;
adrianromero@27136
    50
  v_LineAcum NUMBER;  
adrianromero@27136
    51
  v_BaseLineAlternate NUMBER;
adrianromero@27136
    52
  v_LineAlternate NUMBER;
adrianromero@27136
    53
  v_LineAlternateAcum NUMBER;
adrianromero@27136
    54
  
adrianromero@27136
    55
  v_PriceLine NUMBER;
adrianromero@27136
    56
  v_CalcLine NUMBER;
adrianromero@27136
    57
  v_maxline NUMBER;    
adrianromero@27136
    58
          
adrianromero@27136
    59
  TYPE RECORD IS REF CURSOR;
adrianromero@27136
    60
  Cur_BOM RECORD;          
adrian@94
    61
BEGIN
asier@2084
    62
    
asier@2084
    63
    IF AD_isTriggerEnabled()='N' THEN RETURN;
asier@2078
    64
    END IF;
asier@2078
    65
asier@2078
    66
adrian@94
    67
-- This trigger is used for calculate the applied offers f0r the invoice
adrian@94
    68
eduardo@6017
    69
IF (DELETING) THEN
eduardo@6017
    70
  v_ID:=:OLD.C_INVOICE_ID;
eduardo@6017
    71
ELSE
eduardo@6017
    72
  v_ID:=:NEW.C_INVOICE_ID;
eduardo@6017
    73
END IF;
adrianromero@27136
    74
 IF INSERTING OR UPDATING THEN
adrianromero@27136
    75
   IF (:new.c_orderline_id IS NULL) THEN
adrianromero@27136
    76
     v_Warehouse_ID := NULL;
adrianromero@27136
    77
   ELSE
adrianromero@27136
    78
     SELECT o.m_warehouse_id into v_Warehouse_ID 
adrianromero@27136
    79
     FROM c_orderline ol, c_order o 
adrianromero@27136
    80
     WHERE o.c_order_id = ol.c_order_id and ol.c_orderline_id = :new.c_orderline_id;
adrianromero@27136
    81
   END IF;
adrianromero@27136
    82
 END IF; 
adrian@94
    83
eduardo@6017
    84
  /**************************************************************************
eduardo@6017
    85
   * Calculate Tax, etc.
eduardo@6017
    86
   */
adrianromero@27136
    87
 SELECT processed, stdPrecision, priceprecision, pl.istaxincluded, C_BPARTNER_LOCATION_ID, C_PROJECT_ID, ISSOTRX
adrianromero@27136
    88
   INTO v_Processed, v_Prec, v_PricePrec, v_istaxincluded, v_Bpartner_Location_ID, v_Project_ID, v_IsSOTRX
mikel@17454
    89
 FROM C_Invoice, C_Currency, m_pricelist pl
eduardo@6017
    90
 WHERE C_Invoice.C_Currency_ID = C_Currency.C_Currency_ID
mikel@17454
    91
 AND C_Invoice.m_pricelist_id = pl.m_pricelist_id
eduardo@6017
    92
 AND C_Invoice_ID=v_ID;
sanjota@31526
    93
 v_oldLine:=0;
eduardo@6017
    94
 v_newLineNetAmt:=0;
eduardo@6017
    95
 IF(v_Processed='N') THEN
eduardo@6017
    96
  -- Calculate taxes
unai@26214
    97
  IF (v_istaxincluded = 'Y') THEN
unai@26214
    98
     IF (UPDATING) THEN
unai@26214
    99
        v_oldgrossamt := :old.line_gross_amount;
unai@26214
   100
        v_newgrossamt := :new.line_gross_amount;
unai@26277
   101
     ELSIF (INSERTING) THEN
unai@26214
   102
        v_newgrossamt := :new.line_gross_amount;
unai@26214
   103
     END IF;
adrianromero@27136
   104
   END IF;  
markmm82@31570
   105
  IF(UPDATING OR DELETING) THEN
markmm82@31570
   106
  v_oldLine:= COALESCE(:old.LineNetAmt,0);
eduardo@6017
   107
  END IF;  
eduardo@6017
   108
  IF (INSERTING OR UPDATING) THEN
eduardo@6017
   109
   v_newLineNetAmt := COALESCE(:new.LineNetAmt,0);
eduardo@6017
   110
   v_newLineAlternate := COALESCE(:new.TaxBaseAmt,0);
unai@26214
   111
   IF (UPDATING) THEN
unai@26214
   112
     v_oldLineAlternate := COALESCE(:old.TaxBaseAmt,0);
unai@26214
   113
     IF (:new.AD_Org_ID <> :old.AD_Org_ID OR :new.C_Tax_ID <> :old.C_Tax_ID OR
unai@26214
   114
         v_newLineNetAmt <> v_oldLine OR v_newLineAlternate <> v_oldLineAlternate OR
unai@26214
   115
         :new.line_gross_amount <> :old.line_gross_amount) THEN
unai@26214
   116
       DELETE FROM C_INVOICELINETAX WHERE C_INVOICELINE_ID = :new.C_InvoiceLine_ID;
unai@26214
   117
       v_create := 'Y';
unai@26214
   118
     ELSE
unai@26214
   119
       v_create := 'N';
hari@17336
   120
     END IF;
adrianromero@27136
   121
   END IF;      
adrianromero@27136
   122
   
adrianromero@27136
   123
   IF (v_create = 'Y') THEN   
adrianromero@27136
   124
   IF(:new.C_Tax_ID IS NOT NULL) THEN
adrianromero@27136
   125
     
adrianromero@27136
   126
    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@27136
   127
    IF (v_AsBOM = 'Y') THEN
adrianromero@27136
   128
      -- BOM taxes
adrianromero@27136
   129
      -- Calculate the base for ratios.
adrianromero@27136
   130
      IF (v_istaxincluded = 'Y') THEN
adrianromero@27136
   131
        v_BaseLine := :new.line_gross_amount;
adrianromero@27136
   132
        v_BaseLineAlternate := :new.line_gross_amount;
adrianromero@27136
   133
      ELSE
adrianromero@27136
   134
        v_BaseLine := v_newLineNetAmt;
adrianromero@27136
   135
        v_BaseLineAlternate := v_newLineAlternate;
adrianromero@27136
   136
      END IF;
adrianromero@27136
   137
          -- Calculate total ratio and number of products
adrianromero@27136
   138
      v_TotalRatio := 0;
adrianromero@27136
   139
      v_TotalProducts := 0;      
adrianromero@27136
   140
      FOR Cur_BOM IN (
adrianromero@27136
   141
        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@27136
   142
        SUM(ROUND(BOMQTY * BOMPRICE, v_Prec)) AS RATIO FROM m_product_bom WHERE m_product_id = :NEW.M_PRODUCT_ID
adrianromero@27136
   143
        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@27136
   144
        ORDER BY RATIO ASC )
adrianromero@27136
   145
      LOOP
adrianromero@27136
   146
        v_TotalRatio := v_TotalRatio + Cur_BOM.RATIO;
adrianromero@27136
   147
        v_TotalProducts := v_TotalProducts + 1;
adrianromero@27136
   148
      END LOOP;
adrianromero@27136
   149
      
adrianromero@27136
   150
      -- Calculate taxes based on BOM of products  
adrianromero@27136
   151
      v_LineAlternateAcum := 0;
adrianromero@27136
   152
      v_LineAcum := 0;
adrianromero@27136
   153
      FOR Cur_BOM IN (
adrianromero@27136
   154
        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@27136
   155
        SUM(ROUND(BOMQTY * BOMPRICE, v_Prec)) AS RATIO FROM m_product_bom WHERE m_product_id = :NEW.M_PRODUCT_ID
adrianromero@27136
   156
        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@27136
   157
        ORDER BY RATIO ASC )
adrianromero@27136
   158
      LOOP
adrianromero@27136
   159
        v_TotalProducts := v_TotalProducts - 1;
adrianromero@27136
   160
        IF (v_TotalProducts > 0) THEN
adrianromero@27136
   161
          v_Line := ROUND(v_BaseLine * Cur_BOM.RATIO / v_TotalRatio , v_Prec);
adrianromero@27136
   162
          v_LineAcum := v_LineAcum + v_Line;
adrianromero@27136
   163
          v_LineAlternate := ROUND(v_BaseLineAlternate * Cur_BOM.RATIO / v_TotalRatio , v_Prec);
adrianromero@27136
   164
          v_LineAlternateAcum := v_LineAlternateAcum + v_LineAlternate;
adrianromero@27136
   165
        ELSE -- The last willaccummulate rounding
adrianromero@27136
   166
          v_Line := v_BaseLine - v_LineAcum;
adrianromero@27136
   167
          v_LineAlternate := v_BaseLineAlternate - v_LineAlternateAcum;
adrianromero@27136
   168
        END IF;
adrianromero@27136
   169
        IF (v_istaxincluded = 'Y') THEN
adrianromero@27136
   170
          v_PriceLine := C_GET_NET_PRICE_FROM_GROSS(Cur_BOM.TAX, v_Line, v_LineAlternate, v_PricePrec, :new.qtyinvoiced);
adrianromero@27136
   171
          v_CalcLine := ROUND(:new.qtyinvoiced * v_PriceLine, v_Prec); -- In price including taxes the net and net alternate are equals.
adrianromero@27136
   172
          select coalesce(max(line), 0) into v_maxline from c_invoicelinetax where c_invoiceline_id = :new.C_InvoiceLine_ID;
adrianromero@27136
   173
          C_INVOICELINETAX_INSERT(:new.AD_Org_ID, :new.C_Invoice_ID, :new.C_InvoiceLine_ID, :new.UpdatedBy, Cur_BOM.TAX, Cur_BOM.TAX, v_CalcLine, v_CalcLine, v_Prec);
adrianromero@27136
   174
        ELSE
adrianromero@27136
   175
          C_INVOICELINETAX_INSERT(:new.AD_Org_ID, :new.C_Invoice_ID, :new.C_InvoiceLine_ID, :new.UpdatedBy, Cur_BOM.TAX, Cur_BOM.TAX, v_Line, v_LineAlternate, v_Prec);
adrianromero@27136
   176
        END IF;
adrianromero@27136
   177
      END LOOP;       
adrianromero@27136
   178
    ELSE
adrianromero@27136
   179
      -- Regular taxes
adrianromero@27136
   180
      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);    
adrianromero@27136
   181
    END IF;  
unai@26214
   182
adrianromero@27136
   183
    IF (v_istaxincluded = 'Y') THEN
adrianromero@27136
   184
      C_INVOICELINETAX_ROUNDING(:new.C_InvoiceLine_ID, :new.line_gross_amount, v_newLineNetAmt);
adrianromero@27136
   185
    END IF;  
adrianromero@27136
   186
              
adrianromero@27136
   187
   END IF;
adrianromero@27136
   188
  -- Get Total Tax Amt
adrianromero@27136
   189
   SELECT SUM(TaxAmt)
adrianromero@27136
   190
     INTO v_taxAmt
adrianromero@27136
   191
   FROM C_InvoiceTax
adrianromero@27136
   192
   WHERE C_Invoice_ID=:new.C_Invoice_ID;
adrianromero@27136
   193
  -- DBMS_OUTPUT.PUT_LINE('TaxAmt = ' || v_taxAmt);
adrianromero@27136
   194
   -- Update Header
adrianromero@27136
   195
       -- Get Total Tax Amt
adrianromero@27136
   196
   UPDATE C_Invoice
adrianromero@27136
   197
     SET TotalLines = TotalLines - v_oldLine + v_newLineNetAmt,
adrianromero@27136
   198
     GrandTotal = CASE v_istaxincluded
adrianromero@27136
   199
                     WHEN 'Y' THEN grandtotal - v_oldgrossamt + v_newgrossamt
adrianromero@27136
   200
                     ELSE TotalLines - v_oldLine + v_newLineNetAmt + COALESCE(v_taxAmt, 0)
adrianromero@27136
   201
                  END
adrianromero@27136
   202
   --  Updated = SysDate -- Don't update as otherwise it does not save changes
adrianromero@27136
   203
   WHERE C_Invoice_ID = :new.C_Invoice_ID;
eduardo@6054
   204
   END IF;
eduardo@6017
   205
  ELSE -- DELETING
mikel@17454
   206
   IF (v_istaxincluded = 'Y') THEN
mikel@17454
   207
     v_oldgrossamt := :old.line_gross_amount;
mikel@17454
   208
   END IF;
eduardo@6017
   209
   SELECT SUM(TaxAmt)
eduardo@6017
   210
     INTO v_taxAmt
eduardo@6017
   211
   FROM C_InvoiceTax
eduardo@6017
   212
   WHERE C_Invoice_ID=:old.C_Invoice_ID;
eduardo@6017
   213
  -- DBMS_OUTPUT.PUT_LINE('TaxAmt = ' || v_taxAmt);
eduardo@6017
   214
   -- Update Header
eduardo@6017
   215
   UPDATE C_Invoice
eduardo@6017
   216
     SET TotalLines = TotalLines - v_oldLine + v_newLineNetAmt,
hari@17336
   217
     GrandTotal = CASE v_istaxincluded
hari@17336
   218
                       WHEN 'Y' THEN grandtotal - v_oldgrossamt
hari@17336
   219
                       ELSE TotalLines - v_oldLine + v_newLineNetAmt + COALESCE(v_taxAmt, 0)
sandra@25602
   220
                  END
eduardo@6017
   221
   --  Updated = SysDate -- Don't update as otherwise it does not save changes
eduardo@6017
   222
   WHERE C_Invoice_ID=:old.C_Invoice_ID;
eduardo@6017
   223
  END IF;
hari@17336
   224
  IF (v_istaxincluded = 'Y') THEN
hari@17336
   225
    SELECT totallines, grandtotal INTO v_totallines, v_grandtotal
gorkaion@17348
   226
    FROM C_invoice
hari@17336
   227
    WHERE c_invoice_id = v_id;
gorkaion@17348
   228
    C_INVOICETAX_ROUNDING(v_id, v_grandtotal, v_totallines);
hari@17336
   229
  END IF;
adrianromero@27136
   230
   
eduardo@6017
   231
 END IF;
eduardo@6017
   232
eduardo@6017
   233
antonio@735
   234
END C_INVOICELINE_TRG2
gorkaion@239
   235
]]></body>
adrian@94
   236
    </trigger>
adrian@94
   237
  </database>