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