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