src-db/database/model/triggers/C_INVOICELINE_TRG2.xml
author Mark <markmm82@gmail.com>
Tue, 21 Feb 2017 16:04:04 -0500
changeset 31540 e6fef7749bc4
parent 31526 0c31b06dd168
child 31570 68702618a590
permissions -rw-r--r--
Fixes issue 34993: Update the invoice prepayment amount with correct value
if after create from a paid order line, it updates the line net amount to 0
or it changes from 0 to a another value.

If you create the invoice line from a paid order line, and then the line net amount
changes it value to 0 (by updating qty = 0 or price = 0, for instance), then
previously prepayment was remaining instead of be discarded. So, you may have an
invoice with Total Gross Amount of 0 and a prepayment different than 0.

When you are updating a line with a NEW line net amount = 0 or deleting the line,
it is needed to remove the prepayment of this line from the invoice.

If the OLD line net amount was zero (the prepayment was removed or not taken into
account when creating or updating the line) and it changes
to a non-zero new line net amount value, is necessary take into account the prepaid
order line amount to increase the invoice prepayment amount with its value.

In any other case it is not necessary update the prepayment amount of the invoice.
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
          
markmm82@31540
    59
  v_prepayment NUMBER;
markmm82@31540
    60
adrianromero@27136
    61
  TYPE RECORD IS REF CURSOR;
adrianromero@27136
    62
  Cur_BOM RECORD;          
adrian@94
    63
BEGIN
asier@2084
    64
    
asier@2084
    65
    IF AD_isTriggerEnabled()='N' THEN RETURN;
asier@2078
    66
    END IF;
asier@2078
    67
asier@2078
    68
adrian@94
    69
-- This trigger is used for calculate the applied offers f0r the invoice
adrian@94
    70
eduardo@6017
    71
IF (DELETING) THEN
eduardo@6017
    72
  v_ID:=:OLD.C_INVOICE_ID;
eduardo@6017
    73
ELSE
eduardo@6017
    74
  v_ID:=:NEW.C_INVOICE_ID;
eduardo@6017
    75
END IF;
adrianromero@27136
    76
 IF INSERTING OR UPDATING THEN
adrianromero@27136
    77
   IF (:new.c_orderline_id IS NULL) THEN
adrianromero@27136
    78
     v_Warehouse_ID := NULL;
adrianromero@27136
    79
   ELSE
adrianromero@27136
    80
     SELECT o.m_warehouse_id into v_Warehouse_ID 
adrianromero@27136
    81
     FROM c_orderline ol, c_order o 
adrianromero@27136
    82
     WHERE o.c_order_id = ol.c_order_id and ol.c_orderline_id = :new.c_orderline_id;
adrianromero@27136
    83
   END IF;
adrianromero@27136
    84
 END IF; 
adrian@94
    85
eduardo@6017
    86
  /**************************************************************************
eduardo@6017
    87
   * Calculate Tax, etc.
eduardo@6017
    88
   */
adrianromero@27136
    89
 SELECT processed, stdPrecision, priceprecision, pl.istaxincluded, C_BPARTNER_LOCATION_ID, C_PROJECT_ID, ISSOTRX
adrianromero@27136
    90
   INTO v_Processed, v_Prec, v_PricePrec, v_istaxincluded, v_Bpartner_Location_ID, v_Project_ID, v_IsSOTRX
mikel@17454
    91
 FROM C_Invoice, C_Currency, m_pricelist pl
eduardo@6017
    92
 WHERE C_Invoice.C_Currency_ID = C_Currency.C_Currency_ID
mikel@17454
    93
 AND C_Invoice.m_pricelist_id = pl.m_pricelist_id
eduardo@6017
    94
 AND C_Invoice_ID=v_ID;
sanjota@31526
    95
 v_oldLine:=0;
eduardo@6017
    96
 v_newLineNetAmt:=0;
markmm82@31540
    97
 v_prepayment:=0;
markmm82@31540
    98
 
eduardo@6017
    99
 IF(v_Processed='N') THEN
eduardo@6017
   100
  -- Calculate taxes
unai@26214
   101
  IF (v_istaxincluded = 'Y') THEN
unai@26214
   102
     IF (UPDATING) THEN
unai@26214
   103
        v_oldgrossamt := :old.line_gross_amount;
unai@26214
   104
        v_newgrossamt := :new.line_gross_amount;
unai@26277
   105
     ELSIF (INSERTING) THEN
unai@26214
   106
        v_newgrossamt := :new.line_gross_amount;
unai@26214
   107
     END IF;
adrianromero@27136
   108
   END IF;  
markmm82@31540
   109
  IF (UPDATING OR DELETING) THEN
markmm82@31540
   110
    v_oldLine:= COALESCE(:old.LineNetAmt,0);
markmm82@31540
   111
    IF UPDATING THEN
markmm82@31540
   112
      v_newLineNetAmt:= COALESCE(:new.LineNetAmt,0);
markmm82@31540
   113
    END IF;
markmm82@31540
   114
    
markmm82@31540
   115
    IF (:old.c_orderline_id IS NOT NULL AND (v_oldLine <> 0 OR v_newLineNetAmt <> 0)) THEN
markmm82@31540
   116
      SELECT COALESCE(SUM(fps.paidamt),0)
markmm82@31540
   117
        INTO v_prepayment
markmm82@31540
   118
      FROM fin_payment_schedule fps
markmm82@31540
   119
        JOIN c_order ord ON ord.c_order_id=fps.c_order_id
markmm82@31540
   120
        JOIN c_orderline ordline ON ordline.c_order_id = ord.c_order_id
markmm82@31540
   121
      WHERE ordline.c_orderline_id = :old.c_orderline_id;
markmm82@31540
   122
      IF UPDATING THEN
markmm82@31540
   123
        IF v_newLineNetAmt <> 0 AND v_oldLine = 0 THEN
markmm82@31540
   124
          v_prepayment:= -1 * v_prepayment;
markmm82@31540
   125
        ELSIF v_newLineNetAmt <> 0 AND v_oldLine <> 0 THEN
markmm82@31540
   126
          v_prepayment:= 0;
markmm82@31540
   127
        END IF;
markmm82@31540
   128
      END IF;
markmm82@31540
   129
      UPDATE c_invoice
markmm82@31540
   130
      SET prepaymentamt = prepaymentamt - v_prepayment
markmm82@31540
   131
      WHERE c_invoice_id = v_ID;
markmm82@31540
   132
    END IF;
eduardo@6017
   133
  END IF;  
eduardo@6017
   134
  IF (INSERTING OR UPDATING) THEN
eduardo@6017
   135
   v_newLineNetAmt := COALESCE(:new.LineNetAmt,0);
eduardo@6017
   136
   v_newLineAlternate := COALESCE(:new.TaxBaseAmt,0);
unai@26214
   137
   IF (UPDATING) THEN
unai@26214
   138
     v_oldLineAlternate := COALESCE(:old.TaxBaseAmt,0);
unai@26214
   139
     IF (:new.AD_Org_ID <> :old.AD_Org_ID OR :new.C_Tax_ID <> :old.C_Tax_ID OR
unai@26214
   140
         v_newLineNetAmt <> v_oldLine OR v_newLineAlternate <> v_oldLineAlternate OR
unai@26214
   141
         :new.line_gross_amount <> :old.line_gross_amount) THEN
unai@26214
   142
       DELETE FROM C_INVOICELINETAX WHERE C_INVOICELINE_ID = :new.C_InvoiceLine_ID;
unai@26214
   143
       v_create := 'Y';
unai@26214
   144
     ELSE
unai@26214
   145
       v_create := 'N';
hari@17336
   146
     END IF;
adrianromero@27136
   147
   END IF;      
adrianromero@27136
   148
   
adrianromero@27136
   149
   IF (v_create = 'Y') THEN   
adrianromero@27136
   150
   IF(:new.C_Tax_ID IS NOT NULL) THEN
adrianromero@27136
   151
     
adrianromero@27136
   152
    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
   153
    IF (v_AsBOM = 'Y') THEN
adrianromero@27136
   154
      -- BOM taxes
adrianromero@27136
   155
      -- Calculate the base for ratios.
adrianromero@27136
   156
      IF (v_istaxincluded = 'Y') THEN
adrianromero@27136
   157
        v_BaseLine := :new.line_gross_amount;
adrianromero@27136
   158
        v_BaseLineAlternate := :new.line_gross_amount;
adrianromero@27136
   159
      ELSE
adrianromero@27136
   160
        v_BaseLine := v_newLineNetAmt;
adrianromero@27136
   161
        v_BaseLineAlternate := v_newLineAlternate;
adrianromero@27136
   162
      END IF;
adrianromero@27136
   163
          -- Calculate total ratio and number of products
adrianromero@27136
   164
      v_TotalRatio := 0;
adrianromero@27136
   165
      v_TotalProducts := 0;      
adrianromero@27136
   166
      FOR Cur_BOM IN (
adrianromero@27136
   167
        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
   168
        SUM(ROUND(BOMQTY * BOMPRICE, v_Prec)) AS RATIO FROM m_product_bom WHERE m_product_id = :NEW.M_PRODUCT_ID
adrianromero@27136
   169
        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
   170
        ORDER BY RATIO ASC )
adrianromero@27136
   171
      LOOP
adrianromero@27136
   172
        v_TotalRatio := v_TotalRatio + Cur_BOM.RATIO;
adrianromero@27136
   173
        v_TotalProducts := v_TotalProducts + 1;
adrianromero@27136
   174
      END LOOP;
adrianromero@27136
   175
      
adrianromero@27136
   176
      -- Calculate taxes based on BOM of products  
adrianromero@27136
   177
      v_LineAlternateAcum := 0;
adrianromero@27136
   178
      v_LineAcum := 0;
adrianromero@27136
   179
      FOR Cur_BOM IN (
adrianromero@27136
   180
        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
   181
        SUM(ROUND(BOMQTY * BOMPRICE, v_Prec)) AS RATIO FROM m_product_bom WHERE m_product_id = :NEW.M_PRODUCT_ID
adrianromero@27136
   182
        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
   183
        ORDER BY RATIO ASC )
adrianromero@27136
   184
      LOOP
adrianromero@27136
   185
        v_TotalProducts := v_TotalProducts - 1;
adrianromero@27136
   186
        IF (v_TotalProducts > 0) THEN
adrianromero@27136
   187
          v_Line := ROUND(v_BaseLine * Cur_BOM.RATIO / v_TotalRatio , v_Prec);
adrianromero@27136
   188
          v_LineAcum := v_LineAcum + v_Line;
adrianromero@27136
   189
          v_LineAlternate := ROUND(v_BaseLineAlternate * Cur_BOM.RATIO / v_TotalRatio , v_Prec);
adrianromero@27136
   190
          v_LineAlternateAcum := v_LineAlternateAcum + v_LineAlternate;
adrianromero@27136
   191
        ELSE -- The last willaccummulate rounding
adrianromero@27136
   192
          v_Line := v_BaseLine - v_LineAcum;
adrianromero@27136
   193
          v_LineAlternate := v_BaseLineAlternate - v_LineAlternateAcum;
adrianromero@27136
   194
        END IF;
adrianromero@27136
   195
        IF (v_istaxincluded = 'Y') THEN
adrianromero@27136
   196
          v_PriceLine := C_GET_NET_PRICE_FROM_GROSS(Cur_BOM.TAX, v_Line, v_LineAlternate, v_PricePrec, :new.qtyinvoiced);
adrianromero@27136
   197
          v_CalcLine := ROUND(:new.qtyinvoiced * v_PriceLine, v_Prec); -- In price including taxes the net and net alternate are equals.
adrianromero@27136
   198
          select coalesce(max(line), 0) into v_maxline from c_invoicelinetax where c_invoiceline_id = :new.C_InvoiceLine_ID;
adrianromero@27136
   199
          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
   200
        ELSE
adrianromero@27136
   201
          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
   202
        END IF;
adrianromero@27136
   203
      END LOOP;       
adrianromero@27136
   204
    ELSE
adrianromero@27136
   205
      -- Regular taxes
adrianromero@27136
   206
      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
   207
    END IF;  
unai@26214
   208
adrianromero@27136
   209
    IF (v_istaxincluded = 'Y') THEN
adrianromero@27136
   210
      C_INVOICELINETAX_ROUNDING(:new.C_InvoiceLine_ID, :new.line_gross_amount, v_newLineNetAmt);
adrianromero@27136
   211
    END IF;  
adrianromero@27136
   212
              
adrianromero@27136
   213
   END IF;
adrianromero@27136
   214
  -- Get Total Tax Amt
adrianromero@27136
   215
   SELECT SUM(TaxAmt)
adrianromero@27136
   216
     INTO v_taxAmt
adrianromero@27136
   217
   FROM C_InvoiceTax
adrianromero@27136
   218
   WHERE C_Invoice_ID=:new.C_Invoice_ID;
adrianromero@27136
   219
  -- DBMS_OUTPUT.PUT_LINE('TaxAmt = ' || v_taxAmt);
adrianromero@27136
   220
   -- Update Header
adrianromero@27136
   221
       -- Get Total Tax Amt
adrianromero@27136
   222
   UPDATE C_Invoice
adrianromero@27136
   223
     SET TotalLines = TotalLines - v_oldLine + v_newLineNetAmt,
adrianromero@27136
   224
     GrandTotal = CASE v_istaxincluded
adrianromero@27136
   225
                     WHEN 'Y' THEN grandtotal - v_oldgrossamt + v_newgrossamt
adrianromero@27136
   226
                     ELSE TotalLines - v_oldLine + v_newLineNetAmt + COALESCE(v_taxAmt, 0)
adrianromero@27136
   227
                  END
adrianromero@27136
   228
   --  Updated = SysDate -- Don't update as otherwise it does not save changes
adrianromero@27136
   229
   WHERE C_Invoice_ID = :new.C_Invoice_ID;
eduardo@6054
   230
   END IF;
eduardo@6017
   231
  ELSE -- DELETING
mikel@17454
   232
   IF (v_istaxincluded = 'Y') THEN
mikel@17454
   233
     v_oldgrossamt := :old.line_gross_amount;
mikel@17454
   234
   END IF;
eduardo@6017
   235
   SELECT SUM(TaxAmt)
eduardo@6017
   236
     INTO v_taxAmt
eduardo@6017
   237
   FROM C_InvoiceTax
eduardo@6017
   238
   WHERE C_Invoice_ID=:old.C_Invoice_ID;
eduardo@6017
   239
  -- DBMS_OUTPUT.PUT_LINE('TaxAmt = ' || v_taxAmt);
eduardo@6017
   240
   -- Update Header
eduardo@6017
   241
   UPDATE C_Invoice
eduardo@6017
   242
     SET TotalLines = TotalLines - v_oldLine + v_newLineNetAmt,
hari@17336
   243
     GrandTotal = CASE v_istaxincluded
hari@17336
   244
                       WHEN 'Y' THEN grandtotal - v_oldgrossamt
hari@17336
   245
                       ELSE TotalLines - v_oldLine + v_newLineNetAmt + COALESCE(v_taxAmt, 0)
sandra@25602
   246
                  END
eduardo@6017
   247
   --  Updated = SysDate -- Don't update as otherwise it does not save changes
eduardo@6017
   248
   WHERE C_Invoice_ID=:old.C_Invoice_ID;
eduardo@6017
   249
  END IF;
hari@17336
   250
  IF (v_istaxincluded = 'Y') THEN
hari@17336
   251
    SELECT totallines, grandtotal INTO v_totallines, v_grandtotal
gorkaion@17348
   252
    FROM C_invoice
hari@17336
   253
    WHERE c_invoice_id = v_id;
gorkaion@17348
   254
    C_INVOICETAX_ROUNDING(v_id, v_grandtotal, v_totallines);
hari@17336
   255
  END IF;
adrianromero@27136
   256
   
eduardo@6017
   257
 END IF;
eduardo@6017
   258
eduardo@6017
   259
antonio@735
   260
END C_INVOICELINE_TRG2
gorkaion@239
   261
]]></body>
adrian@94
   262
    </trigger>
adrian@94
   263
  </database>