database/model/triggers/C_INVOICELINE_TRG2.xml
author Adrián Romero <adrian.romero@openbravo.com>
Wed, 05 Dec 2007 20:43:45 +0000
changeset 170 4b5493776a7f
parent 132 33c5ca45fcff
child 239 a30acae847e1
permissions -rw-r--r--
Bug fixed: [ 1845110 ] Database model not in sync with database created
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">
adrian@170
     4
      <body>
adrian@170
     5
adrian@94
     6
adrian@94
     7
adrian@94
     8
adrian@94
     9
   TYPE RECORD IS REF CURSOR;
adrian@94
    10
   Cur_Offer RECORD;
adrian@94
    11
adrian@94
    12
  v_InvoiceLine_Offer_Id NUMBER;
adrian@94
    13
  v_lineno NUMBER :=0;
adrian@94
    14
  v_Price NUMBER;
adrian@94
    15
  v_PriceNew NUMBER;
adrian@94
    16
  v_Amt NUMBER;
adrian@94
    17
  v_BPartner_ID NUMBER;
adrian@94
    18
  v_Order_ID NUMBER;
adrian@94
    19
  v_Insert BOOLEAN :=FALSE;
adrian@94
    20
  v_DateInvoiced DATE;
adrian@94
    21
  v_Precision NUMBER;
adrian@94
    22
  v_PriceList_ID NUMBER;
adrian@94
    23
BEGIN
adrian@94
    24
-- This trigger is used for calculate the applied offers f0r the invoice
adrian@94
    25
adrian@94
    26
adrian@94
    27
adrian@94
    28
 IF DELETING THEN
adrian@94
    29
   DELETE FROM C_INVOICELINE_OFFER
adrian@94
    30
   WHERE C_InvoiceLine_ID = :OLD.C_InvoiceLine_ID;
adrian@94
    31
 END IF;
adrian@94
    32
adrian@94
    33
 IF UPDATING THEN
adrian@94
    34
  IF (    (COALESCE(:NEW.M_Product_ID,0) != COALESCE(:OLD.M_Product_ID,0))
adrian@94
    35
    OR (COALESCE(:NEW.PriceActual,0) != COALESCE(:OLD.PriceActual,0))
adrian@94
    36
    OR (COALESCE(:NEW.QtyInvoiced,0) != COALESCE(:OLD.QtyInvoiced,0))) THEN
adrian@94
    37
  DELETE FROM C_INVOICELINE_OFFER
adrian@94
    38
   WHERE C_InvoiceLine_ID = :NEW.C_InvoiceLine_ID;
adrian@94
    39
   v_Insert := TRUE;
adrian@94
    40
   END IF;
adrian@94
    41
 END IF;
adrian@94
    42
adrian@94
    43
 IF INSERTING OR v_Insert THEN
adrian@94
    44
   SELECT C_BPartner_ID, dateInvoiced, priceprecision, M_PriceList_ID
adrian@94
    45
    INTO v_BPartner_ID, v_DateInvoiced, v_Precision, v_PriceList_ID
adrian@94
    46
     FROM C_INVOICE i,
adrian@94
    47
          C_CURRENCY c
adrian@94
    48
   WHERE C_Invoice_ID = :NEW.C_Invoice_ID
adrian@94
    49
     AND i.C_Currency_ID = c.C_Currency_ID;
adrian@94
    50
adrian@94
    51
adrian@94
    52
   --Get the new "std" price from the Actual price (if actual price is the std price they will be equal)
adrian@94
    53
   v_Price := :NEW.PriceActual;
adrian@94
    54
    FOR Cur_Offer IN (SELECT M_OFFER_ID
adrian@94
    55
         FROM M_OFFER
adrian@94
    56
         WHERE v_DateInvoiced BETWEEN DATEFROM AND COALESCE(DATETO,TO_DATE('31/12/9999','DD/MM/YYYY'))
adrian@94
    57
   AND IsActive = 'Y'
adrian@170
    58
   AND (:NEW.QtyInvoiced &gt;= COALESCE(Qty_From,0) OR Qty_From IS NULL)
adrian@170
    59
   AND (:NEW.QtyInvoiced &lt;= COALESCE(Qty_To,0) OR Qty_To IS NULL)
adrian@94
    60
   AND ((PRICELIST_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM M_OFFER_PRICELIST
adrian@94
    61
           WHERE M_OFFER_ID=M_OFFER.M_OFFER_ID
adrian@94
    62
           AND M_PRICELIST_ID = v_PriceList_ID))
adrian@94
    63
     OR (PRICELIST_SELECTION='N' AND EXISTS(SELECT 1 FROM M_OFFER_PRICELIST
adrian@94
    64
            WHERE M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
    65
            AND M_PRICELIST_ID = v_PriceList_ID)))
adrian@94
    66
         AND ((BPARTNER_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM M_OFFER_BPARTNER
adrian@94
    67
           WHERE M_OFFER_ID=M_OFFER.M_OFFER_ID
adrian@94
    68
           AND C_BPARTNER_ID = v_BPartner_ID))
adrian@94
    69
         OR (BPARTNER_SELECTION='N' AND EXISTS(SELECT 1 FROM M_OFFER_BPARTNER
adrian@94
    70
            WHERE M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
    71
            AND C_BPARTNER_ID = v_BPartner_ID)))
adrian@94
    72
         AND ((BP_GROUP_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM C_BPARTNER B, M_OFFER_BP_GROUP OB
adrian@94
    73
           WHERE OB.M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
    74
           AND B.C_BPARTNER_ID = v_BPartner_ID
adrian@94
    75
           AND OB.C_BP_GROUP_ID = B.C_BP_GROUP_ID))
adrian@94
    76
         OR (BP_GROUP_SELECTION='N' AND EXISTS (SELECT 1 FROM C_BPARTNER B, M_OFFER_BP_GROUP OB
adrian@94
    77
           WHERE OB.M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
    78
           AND B.C_BPARTNER_ID = v_BPartner_ID
adrian@94
    79
           AND OB.C_BP_GROUP_ID = B.C_BP_GROUP_ID)))
adrian@94
    80
         AND ((PRODUCT_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM M_OFFER_PRODUCT
adrian@94
    81
           WHERE M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
    82
           AND M_PRODUCT_ID = :NEW.M_PRODUCT_ID))
adrian@94
    83
         OR (PRODUCT_SELECTION='N' AND EXISTS (SELECT 1 FROM M_OFFER_PRODUCT
adrian@94
    84
            WHERE M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
    85
            AND M_PRODUCT_ID = :NEW.M_PRODUCT_ID)))
adrian@94
    86
         AND ((PROD_CAT_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM M_PRODUCT P, M_OFFER_PROD_CAT OP
adrian@94
    87
           WHERE OP.M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
    88
           AND P.M_PRODUCT_ID = :NEW.M_PRODUCT_ID
adrian@94
    89
           AND OP.M_PRODUCT_CATEGORY_ID = P.M_PRODUCT_CATEGORY_ID))
adrian@94
    90
         OR (PROD_CAT_SELECTION='N' AND EXISTS (SELECT 1 FROM M_PRODUCT P, M_OFFER_PROD_CAT OP
adrian@94
    91
           WHERE OP.M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
    92
           AND P.M_PRODUCT_ID = :NEW.M_PRODUCT_ID
adrian@94
    93
           AND OP.M_PRODUCT_CATEGORY_ID = P.M_PRODUCT_CATEGORY_ID)))
adrian@94
    94
         ORDER BY PRIORITY DESC, M_OFFER_ID) LOOP
adrian@94
    95
    v_Price := M_Get_Offer_Std_Price(Cur_Offer.M_Offer_ID, v_Price);
adrian@94
    96
   END LOOP;
adrian@94
    97
adrian@94
    98
   FOR Cur_Offer IN (SELECT M_OFFER_ID
adrian@94
    99
    FROM M_OFFER
adrian@94
   100
    WHERE v_DateInvoiced BETWEEN DATEFROM AND COALESCE(DATETO,TO_DATE('31/12/9999','DD/MM/YYYY'))
adrian@94
   101
 AND IsActive = 'Y'
adrian@170
   102
 AND (:NEW.QtyInvoiced &gt;= COALESCE(Qty_From,0) OR Qty_From IS NULL)
adrian@170
   103
   AND (:NEW.QtyInvoiced &lt;= COALESCE(Qty_To,0) OR Qty_To IS NULL)
adrian@94
   104
   AND ((PRICELIST_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM M_OFFER_PRICELIST
adrian@94
   105
           WHERE M_OFFER_ID=M_OFFER.M_OFFER_ID
adrian@94
   106
           AND M_PRICELIST_ID = v_PriceList_ID))
adrian@94
   107
     OR (PRICELIST_SELECTION='N' AND EXISTS(SELECT 1 FROM M_OFFER_PRICELIST
adrian@94
   108
            WHERE M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
   109
            AND M_PRICELIST_ID = v_PriceList_ID)))
adrian@94
   110
    AND ((BPARTNER_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM M_OFFER_BPARTNER
adrian@94
   111
      WHERE M_OFFER_ID=M_OFFER.M_OFFER_ID
adrian@94
   112
      AND C_BPARTNER_ID = v_BPartner_ID))
adrian@94
   113
    OR (BPARTNER_SELECTION='N' AND EXISTS(SELECT 1 FROM M_OFFER_BPARTNER
adrian@94
   114
       WHERE M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
   115
       AND C_BPARTNER_ID = v_BPartner_ID)))
adrian@94
   116
    AND ((BP_GROUP_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM C_BPARTNER B, M_OFFER_BP_GROUP OB
adrian@94
   117
      WHERE OB.M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
   118
      AND B.C_BPARTNER_ID = v_BPartner_ID
adrian@94
   119
      AND OB.C_BP_GROUP_ID = B.C_BP_GROUP_ID))
adrian@94
   120
    OR (BP_GROUP_SELECTION='N' AND EXISTS (SELECT 1 FROM C_BPARTNER B, M_OFFER_BP_GROUP OB
adrian@94
   121
      WHERE OB.M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
   122
      AND B.C_BPARTNER_ID = v_BPartner_ID
adrian@94
   123
      AND OB.C_BP_GROUP_ID = B.C_BP_GROUP_ID)))
adrian@94
   124
    AND ((PRODUCT_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM M_OFFER_PRODUCT
adrian@94
   125
      WHERE M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
   126
      AND M_PRODUCT_ID = :NEW.M_PRODUCT_ID))
adrian@94
   127
    OR (PRODUCT_SELECTION='N' AND EXISTS (SELECT 1 FROM M_OFFER_PRODUCT
adrian@94
   128
       WHERE M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
   129
       AND M_PRODUCT_ID = :NEW.M_PRODUCT_ID)))
adrian@94
   130
    AND ((PROD_CAT_SELECTION='Y' AND NOT EXISTS (SELECT 1 FROM M_PRODUCT P, M_OFFER_PROD_CAT OP
adrian@94
   131
      WHERE OP.M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
   132
      AND P.M_PRODUCT_ID = :NEW.M_PRODUCT_ID
adrian@94
   133
      AND OP.M_PRODUCT_CATEGORY_ID = P.M_PRODUCT_CATEGORY_ID))
adrian@94
   134
    OR (PROD_CAT_SELECTION='N' AND EXISTS (SELECT 1 FROM M_PRODUCT P, M_OFFER_PROD_CAT OP
adrian@94
   135
      WHERE OP.M_OFFER_ID = M_OFFER.M_OFFER_ID
adrian@94
   136
      AND P.M_PRODUCT_ID = :NEW.M_PRODUCT_ID
adrian@94
   137
      AND OP.M_PRODUCT_CATEGORY_ID = P.M_PRODUCT_CATEGORY_ID)))
adrian@94
   138
    ORDER BY PRIORITY, M_OFFER_ID DESC) LOOP
adrian@94
   139
   Ad_Sequence_Next('C_InvoiceLine_Offer', :NEW.AD_Client_ID, v_InvoiceLine_Offer_ID);
adrian@94
   140
   v_lineno := v_lineno + 10;
adrian@94
   141
   v_PriceNew := M_Get_Offer_Price(Cur_Offer.M_Offer_ID, v_Price);
adrian@94
   142
   v_Amt := v_Price - v_PriceNew;
adrian@94
   143
adrian@94
   144
   INSERT INTO C_INVOICELINE_OFFER
adrian@94
   145
       (C_INVOICELINE_OFFER_ID, AD_CLIENT_ID, AD_ORG_ID, ISACTIVE,
adrian@94
   146
      CREATED, CREATEDBY, UPDATED, UPDATEDBY,
adrian@94
   147
      C_INVOICELINE_ID, LINE, M_OFFER_ID, PRICEOFFER, AMTOFFER)
adrian@94
   148
   VALUES
adrian@94
   149
       (v_InvoiceLine_Offer_ID, :NEW.AD_Client_ID, :NEW.AD_Org_ID, :NEW.IsActive,
adrian@94
   150
      Now(),:NEW.CreatedBy, Now(),:NEW.UpdatedBy,
adrian@94
   151
     :NEW.C_InvoiceLine_ID, v_lineno, Cur_Offer.M_Offer_Id, ROUND(v_Price,v_Precision), ROUND(v_Amt, v_Precision));
adrian@94
   152
    v_Price := v_PriceNew;
adrian@94
   153
  END LOOP;
adrian@94
   154
 END IF;
adrian@94
   155
adrian@94
   156
END C_InvoiceLine_Trg2 
adrian@170
   157
adrian@170
   158
</body>
adrian@94
   159
    </trigger>
adrian@94
   160
  </database>