src-db/database/model/triggers/C_INVOICELINE_TRG2.xml
author Mikel Irurita <mikel.irurita@openbravo.com>
Thu, 12 Jul 2012 17:11:01 +0200
changeset 17454 745fd4a939d1
parent 17348 5671a6587aa6
child 18314 6113c22ee84c
permissions -rw-r--r--
Fixes issue 21053: C_INVOICELINE_TRG2: PIT logic not working
<?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-2008 Openbravo SLU
* All Rights Reserved.
* Contributor(s):  ______________________________________.
************************************************************************/





   TYPE RECORD IS REF CURSOR;
   Cur_Offer RECORD;

  v_InvoiceLine_Offer_ID VARCHAR2(32);
  v_lineno NUMBER:=0;
  v_Price NUMBER;
  v_PriceNew NUMBER;
  v_Amt NUMBER;
  v_BPartner_ID VARCHAR2(32);
  v_Order_ID VARCHAR2(32);
  v_Insert BOOLEAN :=FALSE;
  v_DateInvoiced DATE;
  v_Precision NUMBER;
  v_PriceList_ID VARCHAR2(32);
  v_Processed C_ORDER.PROCESSED%TYPE;
  v_ID VARCHAR2(32);
  v_Issotrx CHAR(1);
  v_pricecancelAD CHAR(1);
  v_oldLine NUMBER;
  v_newLineNetAmt NUMBER;
  v_newLineAlternate NUMBER;
  v_taxAmt NUMBER;
  v_Prec C_CURRENCY.STDPRECISION%TYPE;
  v_BaseAmount C_TAX.BASEAMOUNT%TYPE;  
  v_istaxincluded CHAR(1) ;
  v_oldGrossAmt NUMBER:=0;
  v_newGrossAmt NUMBER:=0;
  v_totallines NUMBER:=0;
  v_grandtotal NUMBER:=0;
        
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 UPDATING THEN
  IF (    (COALESCE(:NEW.M_Product_ID,'0') != COALESCE(:OLD.M_Product_ID,'0'))
    OR (COALESCE(:NEW.PriceActual,0) != COALESCE(:OLD.PriceActual,0))
    OR (COALESCE(:NEW.QtyInvoiced,0) != COALESCE(:OLD.QtyInvoiced,0))) THEN
  DELETE FROM C_INVOICELINE_OFFER
   WHERE C_InvoiceLine_ID = :NEW.C_InvoiceLine_ID;
   v_Insert := TRUE;
   END IF;
 END IF;
 
 IF INSERTING OR v_Insert THEN
   SELECT C_BPartner_ID, dateInvoiced, priceprecision, i.M_PriceList_ID,p.istaxincluded
    INTO v_BPartner_ID, v_DateInvoiced, v_Precision, v_PriceList_ID, v_istaxincluded
     FROM C_INVOICE i
             JOIN m_pricelist p ON i.m_pricelist_id = p.m_pricelist_id,

          C_CURRENCY c
          
   WHERE C_Invoice_ID = :NEW.C_Invoice_ID
     AND i.C_Currency_ID = c.C_Currency_ID;

   IF (v_istaxincluded = 'Y') THEN
     IF (UPDATING) THEN
        v_oldgrossamt := :old.line_gross_amount;
        v_newgrossamt := :new.line_gross_amount;
     ELSE
        v_newgrossamt := :new.line_gross_amount;
     END IF;
   END IF;

 
   --Get the new "std" price from the Actual price (if actual price is the std price they will be equal)
   v_Price := :NEW.PriceActual;
    FOR Cur_Offer IN (SELECT M_OFFER_ID
         FROM M_OFFER
         WHERE v_DateInvoiced BETWEEN DATEFROM AND COALESCE(DATETO,TO_DATE('31-12-9999','DD-MM-YYYY'))
   AND IsActive = 'Y'
   AND (:NEW.QtyInvoiced >= COALESCE(Qty_From,0) OR Qty_From IS NULL)
   AND (:NEW.QtyInvoiced <= COALESCE(Qty_To,0) OR Qty_To IS NULL)
   AND ((PRICELIST_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM M_OFFER_PRICELIST
           WHERE M_OFFER_ID=M_OFFER.M_OFFER_ID
           AND M_PRICELIST_ID = v_PriceList_ID))
     OR (PRICELIST_SELECTION='N' AND EXISTS(SELECT 1 FROM M_OFFER_PRICELIST
            WHERE M_OFFER_ID = M_OFFER.M_OFFER_ID
            AND M_PRICELIST_ID = v_PriceList_ID)))
         AND ((BPARTNER_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM M_OFFER_BPARTNER
           WHERE M_OFFER_ID=M_OFFER.M_OFFER_ID
           AND C_BPARTNER_ID = v_BPartner_ID))
         OR (BPARTNER_SELECTION='N' AND EXISTS(SELECT 1 FROM M_OFFER_BPARTNER
            WHERE M_OFFER_ID = M_OFFER.M_OFFER_ID
            AND C_BPARTNER_ID = v_BPartner_ID)))
         AND ((BP_GROUP_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM C_BPARTNER B, M_OFFER_BP_GROUP OB
           WHERE OB.M_OFFER_ID = M_OFFER.M_OFFER_ID
           AND B.C_BPARTNER_ID = v_BPartner_ID
           AND OB.C_BP_GROUP_ID = B.C_BP_GROUP_ID))
         OR (BP_GROUP_SELECTION='N' AND EXISTS (SELECT 1 FROM C_BPARTNER B, M_OFFER_BP_GROUP OB
           WHERE OB.M_OFFER_ID = M_OFFER.M_OFFER_ID
           AND B.C_BPARTNER_ID = v_BPartner_ID
           AND OB.C_BP_GROUP_ID = B.C_BP_GROUP_ID)))
         AND ((PRODUCT_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM M_OFFER_PRODUCT
           WHERE M_OFFER_ID = M_OFFER.M_OFFER_ID
           AND M_PRODUCT_ID = :NEW.M_PRODUCT_ID))
         OR (PRODUCT_SELECTION='N' AND EXISTS (SELECT 1 FROM M_OFFER_PRODUCT
            WHERE M_OFFER_ID = M_OFFER.M_OFFER_ID
            AND M_PRODUCT_ID = :NEW.M_PRODUCT_ID)))
         AND ((PROD_CAT_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM M_PRODUCT P, M_OFFER_PROD_CAT OP
           WHERE OP.M_OFFER_ID = M_OFFER.M_OFFER_ID
           AND P.M_PRODUCT_ID = :NEW.M_PRODUCT_ID
           AND OP.M_PRODUCT_CATEGORY_ID = P.M_PRODUCT_CATEGORY_ID))
         OR (PROD_CAT_SELECTION='N' AND EXISTS (SELECT 1 FROM M_PRODUCT P, M_OFFER_PROD_CAT OP
           WHERE OP.M_OFFER_ID = M_OFFER.M_OFFER_ID
           AND P.M_PRODUCT_ID = :NEW.M_PRODUCT_ID
           AND OP.M_PRODUCT_CATEGORY_ID = P.M_PRODUCT_CATEGORY_ID)))
         ORDER BY PRIORITY DESC, M_OFFER_ID) LOOP
    v_Price := M_Get_Offer_Std_Price(Cur_Offer.M_Offer_ID, v_Price);
   END LOOP;

   FOR Cur_Offer IN (SELECT M_OFFER_ID
    FROM M_OFFER
    WHERE v_DateInvoiced BETWEEN DATEFROM AND COALESCE(DATETO,TO_DATE('31-12-9999','DD-MM-YYYY'))
 AND IsActive = 'Y'
 AND (:NEW.QtyInvoiced >= COALESCE(Qty_From,0) OR Qty_From IS NULL)
   AND (:NEW.QtyInvoiced <= COALESCE(Qty_To,0) OR Qty_To IS NULL)
   AND ((PRICELIST_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM M_OFFER_PRICELIST
           WHERE M_OFFER_ID=M_OFFER.M_OFFER_ID
           AND M_PRICELIST_ID = v_PriceList_ID))
     OR (PRICELIST_SELECTION='N' AND EXISTS(SELECT 1 FROM M_OFFER_PRICELIST
            WHERE M_OFFER_ID = M_OFFER.M_OFFER_ID
            AND M_PRICELIST_ID = v_PriceList_ID)))
    AND ((BPARTNER_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM M_OFFER_BPARTNER
      WHERE M_OFFER_ID=M_OFFER.M_OFFER_ID
      AND C_BPARTNER_ID = v_BPartner_ID))
    OR (BPARTNER_SELECTION='N' AND EXISTS(SELECT 1 FROM M_OFFER_BPARTNER
       WHERE M_OFFER_ID = M_OFFER.M_OFFER_ID
       AND C_BPARTNER_ID = v_BPartner_ID)))
    AND ((BP_GROUP_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM C_BPARTNER B, M_OFFER_BP_GROUP OB
      WHERE OB.M_OFFER_ID = M_OFFER.M_OFFER_ID
      AND B.C_BPARTNER_ID = v_BPartner_ID
      AND OB.C_BP_GROUP_ID = B.C_BP_GROUP_ID))
    OR (BP_GROUP_SELECTION='N' AND EXISTS (SELECT 1 FROM C_BPARTNER B, M_OFFER_BP_GROUP OB
      WHERE OB.M_OFFER_ID = M_OFFER.M_OFFER_ID
      AND B.C_BPARTNER_ID = v_BPartner_ID
      AND OB.C_BP_GROUP_ID = B.C_BP_GROUP_ID)))
    AND ((PRODUCT_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM M_OFFER_PRODUCT
      WHERE M_OFFER_ID = M_OFFER.M_OFFER_ID
      AND M_PRODUCT_ID = :NEW.M_PRODUCT_ID))
    OR (PRODUCT_SELECTION='N' AND EXISTS (SELECT 1 FROM M_OFFER_PRODUCT
       WHERE M_OFFER_ID = M_OFFER.M_OFFER_ID
       AND M_PRODUCT_ID = :NEW.M_PRODUCT_ID)))
    AND ((PROD_CAT_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM M_PRODUCT P, M_OFFER_PROD_CAT OP
      WHERE OP.M_OFFER_ID = M_OFFER.M_OFFER_ID
      AND P.M_PRODUCT_ID = :NEW.M_PRODUCT_ID
      AND OP.M_PRODUCT_CATEGORY_ID = P.M_PRODUCT_CATEGORY_ID))
    OR (PROD_CAT_SELECTION='N' AND EXISTS (SELECT 1 FROM M_PRODUCT P, M_OFFER_PROD_CAT OP
      WHERE OP.M_OFFER_ID = M_OFFER.M_OFFER_ID
      AND P.M_PRODUCT_ID = :NEW.M_PRODUCT_ID
      AND OP.M_PRODUCT_CATEGORY_ID = P.M_PRODUCT_CATEGORY_ID)))
    ORDER BY PRIORITY, M_OFFER_ID DESC) LOOP
   Ad_Sequence_Next('C_InvoiceLine_Offer', :NEW.AD_Client_ID, v_InvoiceLine_Offer_ID);
   v_lineno := v_lineno + 10;
   v_PriceNew := M_Get_Offer_Price(Cur_Offer.M_Offer_ID, v_Price);
   v_Amt := v_Price - v_PriceNew;
   v_pricecancelAD := 'N';
	IF(:NEW.C_ORDERLINE_ID IS NOT NULL) THEN
	  	SELECT o.issotrx,ol.CancelPriceAD into v_Issotrx,v_pricecancelAD FROM C_ORDER o,C_ORDERLINE ol WHERE ol.C_ORDERLINE_ID = :NEW.C_ORDERLINE_ID AND o.C_ORDER_ID = ol.C_ORDER_ID;
		IF((v_Issotrx = 'Y' AND v_pricecancelAD <> 'Y') OR v_Issotrx = 'N') THEN
		   INSERT INTO C_INVOICELINE_OFFER
		       (C_INVOICELINE_OFFER_ID, AD_CLIENT_ID, AD_ORG_ID, ISACTIVE,
		      CREATED, CREATEDBY, UPDATED, UPDATEDBY,
		      C_INVOICELINE_ID, LINE, M_OFFER_ID, PRICEOFFER, AMTOFFER)
		   VALUES
		       (v_InvoiceLine_Offer_ID, :NEW.AD_Client_ID, :NEW.AD_Org_ID, :NEW.IsActive,
		      now(),:NEW.CreatedBy, now(),:NEW.UpdatedBy,
		     :NEW.C_InvoiceLine_ID, v_lineno, Cur_Offer.M_Offer_Id, ROUND(v_Price,v_Precision), ROUND(v_Amt, v_Precision));
	     END IF;
    ELSE
    	INSERT INTO C_INVOICELINE_OFFER
       (C_INVOICELINE_OFFER_ID, AD_CLIENT_ID, AD_ORG_ID, ISACTIVE,
      CREATED, CREATEDBY, UPDATED, UPDATEDBY,
      C_INVOICELINE_ID, LINE, M_OFFER_ID, PRICEOFFER, AMTOFFER)
   	VALUES
       (v_InvoiceLine_Offer_ID, :NEW.AD_Client_ID, :NEW.AD_Org_ID, :NEW.IsActive,
      now(),:NEW.CreatedBy, now(),:NEW.UpdatedBy,
     :NEW.C_InvoiceLine_ID, v_lineno, Cur_Offer.M_Offer_Id, ROUND(v_Price,v_Precision), ROUND(v_Amt, v_Precision));
    END IF;
    v_Price := v_PriceNew;
  END LOOP;
 END IF;

  /**************************************************************************
   * Calculate Tax, etc.
   */
 SELECT processed, stdPrecision, pl.istaxincluded
   INTO v_Processed, v_Prec, v_istaxincluded
 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(UPDATING OR DELETING) THEN
  v_oldLine:= COALESCE(:old.LineNetAmt,0);
  END IF;  
  IF (INSERTING OR UPDATING) THEN
   DELETE FROM C_INVOICELINETAX WHERE C_INVOICELINE_ID = :new.C_InvoiceLine_ID;
   v_newLineNetAmt := COALESCE(:new.LineNetAmt,0);
   v_newLineAlternate := COALESCE(:new.TaxBaseAmt,0);
   IF(:new.C_Tax_ID IS NOT NULL) THEN
     SELECT BaseAmount INTO v_BaseAmount
     FROM C_TAX
     WHERE C_TAX_ID = :new.C_Tax_ID;
     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);
     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;
  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>