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.
<?xml version="1.0"?>
  <database name="TRIGGER C_INVOICELINE_TRG2">
    <trigger name="C_INVOICELINE_TRG2" table="C_INVOICELINE" fires="after" insert="true" update="true" delete="true" foreach="row">
      <body><![CDATA[
/*************************************************************************
* The contents of this file are subject to the Openbravo  Public  License
* Version  1.1  (the  "License"),  being   the  Mozilla   Public  License
* Version 1.1  with a permitted attribution clause; you may not  use this
* file except in compliance with the License. You  may  obtain  a copy of
* the License at http://www.openbravo.com/legal/license.html
* Software distributed under the License  is  distributed  on  an "AS IS"
* basis, WITHOUT WARRANTY OF ANY KIND, either express or implied. See the
* License for the specific  language  governing  rights  and  limitations
* under the License.
* The Original Code is Openbravo ERP.
* The Initial Developer of the Original Code is Openbravo SLU
* All portions are Copyright (C) 2001-2017 Openbravo SLU
* All Rights Reserved.
* Contributor(s):  ______________________________________.
************************************************************************/



  v_Processed C_ORDER.PROCESSED%TYPE;
  v_ID VARCHAR2(32);
  v_oldLine NUMBER;
  v_newLineNetAmt NUMBER;
  v_newLineAlternate NUMBER;
  v_taxAmt NUMBER;
  v_Prec C_CURRENCY.STDPRECISION%TYPE;
  v_PricePrec C_CURRENCY.PRICEPRECISION%TYPE;
  v_istaxincluded CHAR(1) ;
  v_oldGrossAmt NUMBER:=0;
  v_newGrossAmt NUMBER:=0;
  v_totallines NUMBER:=0;
  v_grandtotal NUMBER:=0;
  v_oldLineAlternate NUMBER;
  v_create CHAR(1):='Y';  
  
  v_Warehouse_ID VARCHAR2(32);
  v_BPartner_Location_ID VARCHAR2(32);
  v_Project_ID VARCHAR2(32);
  v_IsSOTRX CHAR(1);
  v_AsBOM CHAR(1);  
  v_TotalRatio NUMBER;
  v_TotalProducts NUMBER;
  
  v_BaseLine NUMBER;
  v_Line NUMBER;
  v_LineAcum NUMBER;  
  v_BaseLineAlternate NUMBER;
  v_LineAlternate NUMBER;
  v_LineAlternateAcum NUMBER;
  
  v_PriceLine NUMBER;
  v_CalcLine NUMBER;
  v_maxline NUMBER;    
          
  TYPE RECORD IS REF CURSOR;
  Cur_BOM RECORD;          
BEGIN
    
    IF AD_isTriggerEnabled()='N' THEN RETURN;
    END IF;


-- This trigger is used for calculate the applied offers f0r the invoice

IF (DELETING) THEN
  v_ID:=:OLD.C_INVOICE_ID;
ELSE
  v_ID:=:NEW.C_INVOICE_ID;
END IF;
 IF INSERTING OR UPDATING THEN
   IF (:new.c_orderline_id IS NULL) THEN
     v_Warehouse_ID := NULL;
   ELSE
     SELECT o.m_warehouse_id into v_Warehouse_ID 
     FROM c_orderline ol, c_order o 
     WHERE o.c_order_id = ol.c_order_id and ol.c_orderline_id = :new.c_orderline_id;
   END IF;
 END IF; 

  /**************************************************************************
   * Calculate Tax, etc.
   */
 SELECT processed, stdPrecision, priceprecision, pl.istaxincluded, C_BPARTNER_LOCATION_ID, C_PROJECT_ID, ISSOTRX
   INTO v_Processed, v_Prec, v_PricePrec, v_istaxincluded, v_Bpartner_Location_ID, v_Project_ID, v_IsSOTRX
 FROM C_Invoice, C_Currency, m_pricelist pl
 WHERE C_Invoice.C_Currency_ID = C_Currency.C_Currency_ID
 AND C_Invoice.m_pricelist_id = pl.m_pricelist_id
 AND C_Invoice_ID=v_ID;
 v_oldLine:=0;
 v_newLineNetAmt:=0;
 IF(v_Processed='N') THEN
  -- Calculate taxes
  IF (v_istaxincluded = 'Y') THEN
     IF (UPDATING) THEN
        v_oldgrossamt := :old.line_gross_amount;
        v_newgrossamt := :new.line_gross_amount;
     ELSIF (INSERTING) THEN
        v_newgrossamt := :new.line_gross_amount;
     END IF;
   END IF;  
  IF(UPDATING OR DELETING) THEN
  v_oldLine:= COALESCE(:old.LineNetAmt,0);
  END IF;  
  IF (INSERTING OR UPDATING) THEN
   v_newLineNetAmt := COALESCE(:new.LineNetAmt,0);
   v_newLineAlternate := COALESCE(:new.TaxBaseAmt,0);
   IF (UPDATING) THEN
     v_oldLineAlternate := COALESCE(:old.TaxBaseAmt,0);
     IF (:new.AD_Org_ID <> :old.AD_Org_ID OR :new.C_Tax_ID <> :old.C_Tax_ID OR
         v_newLineNetAmt <> v_oldLine OR v_newLineAlternate <> v_oldLineAlternate OR
         :new.line_gross_amount <> :old.line_gross_amount) THEN
       DELETE FROM C_INVOICELINETAX WHERE C_INVOICELINE_ID = :new.C_InvoiceLine_ID;
       v_create := 'Y';
     ELSE
       v_create := 'N';
     END IF;
   END IF;      
   
   IF (v_create = 'Y') THEN   
   IF(:new.C_Tax_ID IS NOT NULL) THEN
     
    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;
    IF (v_AsBOM = 'Y') THEN
      -- BOM taxes
      -- Calculate the base for ratios.
      IF (v_istaxincluded = 'Y') THEN
        v_BaseLine := :new.line_gross_amount;
        v_BaseLineAlternate := :new.line_gross_amount;
      ELSE
        v_BaseLine := v_newLineNetAmt;
        v_BaseLineAlternate := v_newLineAlternate;
      END IF;
          -- Calculate total ratio and number of products
      v_TotalRatio := 0;
      v_TotalProducts := 0;      
      FOR Cur_BOM IN (
        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,
        SUM(ROUND(BOMQTY * BOMPRICE, v_Prec)) AS RATIO FROM m_product_bom WHERE m_product_id = :NEW.M_PRODUCT_ID
        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)
        ORDER BY RATIO ASC )
      LOOP
        v_TotalRatio := v_TotalRatio + Cur_BOM.RATIO;
        v_TotalProducts := v_TotalProducts + 1;
      END LOOP;
      
      -- Calculate taxes based on BOM of products  
      v_LineAlternateAcum := 0;
      v_LineAcum := 0;
      FOR Cur_BOM IN (
        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,
        SUM(ROUND(BOMQTY * BOMPRICE, v_Prec)) AS RATIO FROM m_product_bom WHERE m_product_id = :NEW.M_PRODUCT_ID
        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)
        ORDER BY RATIO ASC )
      LOOP
        v_TotalProducts := v_TotalProducts - 1;
        IF (v_TotalProducts > 0) THEN
          v_Line := ROUND(v_BaseLine * Cur_BOM.RATIO / v_TotalRatio , v_Prec);
          v_LineAcum := v_LineAcum + v_Line;
          v_LineAlternate := ROUND(v_BaseLineAlternate * Cur_BOM.RATIO / v_TotalRatio , v_Prec);
          v_LineAlternateAcum := v_LineAlternateAcum + v_LineAlternate;
        ELSE -- The last willaccummulate rounding
          v_Line := v_BaseLine - v_LineAcum;
          v_LineAlternate := v_BaseLineAlternate - v_LineAlternateAcum;
        END IF;
        IF (v_istaxincluded = 'Y') THEN
          v_PriceLine := C_GET_NET_PRICE_FROM_GROSS(Cur_BOM.TAX, v_Line, v_LineAlternate, v_PricePrec, :new.qtyinvoiced);
          v_CalcLine := ROUND(:new.qtyinvoiced * v_PriceLine, v_Prec); -- In price including taxes the net and net alternate are equals.
          select coalesce(max(line), 0) into v_maxline from c_invoicelinetax where c_invoiceline_id = :new.C_InvoiceLine_ID;
          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);
        ELSE
          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);
        END IF;
      END LOOP;       
    ELSE
      -- Regular taxes
      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);    
    END IF;  

    IF (v_istaxincluded = 'Y') THEN
      C_INVOICELINETAX_ROUNDING(:new.C_InvoiceLine_ID, :new.line_gross_amount, v_newLineNetAmt);
    END IF;  
              
   END IF;
  -- Get Total Tax Amt
   SELECT SUM(TaxAmt)
     INTO v_taxAmt
   FROM C_InvoiceTax
   WHERE C_Invoice_ID=:new.C_Invoice_ID;
  -- DBMS_OUTPUT.PUT_LINE('TaxAmt = ' || v_taxAmt);
   -- Update Header
       -- Get Total Tax Amt
   UPDATE C_Invoice
     SET TotalLines = TotalLines - v_oldLine + v_newLineNetAmt,
     GrandTotal = CASE v_istaxincluded
                     WHEN 'Y' THEN grandtotal - v_oldgrossamt + v_newgrossamt
                     ELSE TotalLines - v_oldLine + v_newLineNetAmt + COALESCE(v_taxAmt, 0)
                  END
   --  Updated = SysDate -- Don't update as otherwise it does not save changes
   WHERE C_Invoice_ID = :new.C_Invoice_ID;
   END IF;
  ELSE -- DELETING
   IF (v_istaxincluded = 'Y') THEN
     v_oldgrossamt := :old.line_gross_amount;
   END IF;
   SELECT SUM(TaxAmt)
     INTO v_taxAmt
   FROM C_InvoiceTax
   WHERE C_Invoice_ID=:old.C_Invoice_ID;
  -- DBMS_OUTPUT.PUT_LINE('TaxAmt = ' || v_taxAmt);
   -- Update Header
   UPDATE C_Invoice
     SET TotalLines = TotalLines - v_oldLine + v_newLineNetAmt,
     GrandTotal = CASE v_istaxincluded
                       WHEN 'Y' THEN grandtotal - v_oldgrossamt
                       ELSE TotalLines - v_oldLine + v_newLineNetAmt + COALESCE(v_taxAmt, 0)
                  END
   --  Updated = SysDate -- Don't update as otherwise it does not save changes
   WHERE C_Invoice_ID=:old.C_Invoice_ID;
  END IF;
  IF (v_istaxincluded = 'Y') THEN
    SELECT totallines, grandtotal INTO v_totallines, v_grandtotal
    FROM C_invoice
    WHERE c_invoice_id = v_id;
    C_INVOICETAX_ROUNDING(v_id, v_grandtotal, v_totallines);
  END IF;
   
 END IF;


END C_INVOICELINE_TRG2
]]></body>
    </trigger>
  </database>