src-db/database/model/functions/GENERATE_AVERAGE_COSTS.xml
author Juan Pablo Aroztegi <juanpablo.aroztegi@openbravo.com>
Wed, 03 Sep 2008 17:55:37 +0000
changeset 1605 8a0fe0193bef
parent 756 ae11e4610537
child 1679 66fc15a51a29
permissions -rw-r--r--
Merge r2.5x intro trunk
carlos@0
     1
<?xml version="1.0"?>
adrian@94
     2
  <database name="FUNCTION GENERATE_AVERAGE_COSTS">
adrian@94
     3
    <function name="GENERATE_AVERAGE_COSTS" type="NULL">
juanpablo@1605
     4
      <parameter name="p_pinstance_id" type="VARCHAR" mode="in">
antonio@735
     5
        <default/>
antonio@735
     6
      </parameter>
gorkaion@239
     7
      <body><![CDATA[/*************************************************************************
carlos@0
     8
* The contents of this file are subject to the Openbravo  Public  License
carlos@0
     9
* Version  1.0  (the  "License"),  being   the  Mozilla   Public  License
carlos@0
    10
* Version 1.1  with a permitted attribution clause; you may not  use this
carlos@0
    11
* file except in compliance with the License. You  may  obtain  a copy of
carlos@0
    12
* the License at http://www.openbravo.com/legal/license.html
carlos@0
    13
* Software distributed under the License  is  distributed  on  an "AS IS"
carlos@0
    14
* basis, WITHOUT WARRANTY OF ANY KIND, either express or implied. See the
carlos@0
    15
* License for the specific  language  governing  rights  and  limitations
carlos@0
    16
* under the License.
carlos@0
    17
* The Original Code is Openbravo ERP.
carlos@0
    18
* The Initial Developer of the Original Code is Openbravo SL
carlos@0
    19
* All portions are Copyright (C) 2001-2006 Openbravo SL
carlos@0
    20
* All Rights Reserved.
carlos@0
    21
* Contributor(s):  ______________________________________.
carlos@0
    22
************************************************************************/
carlos@0
    23
  -- Logistice
carlos@0
    24
  v_ResultStr VARCHAR2(2000):='';
carlos@0
    25
  v_Result NUMBER;
carlos@0
    26
  v_Message VARCHAR2(2000):='';
juanpablo@1605
    27
  v_Record_ID VARCHAR2(32);
carlos@0
    28
  v_Date DATE;
carlos@0
    29
  v_Qty NUMBER;
carlos@0
    30
  v_Cost NUMBER;
juanpablo@1605
    31
  v_User VARCHAR2(32);
carlos@0
    32
  v_Price NUMBER;
carlos@0
    33
  v_DateOld DATE;
carlos@0
    34
  v_CumQty NUMBER;
carlos@0
    35
  v_Processed CHAR(1) ;
carlos@0
    36
  v_count NUMBER;
carlos@0
    37
  v_Deleted NUMBER;
carlos@0
    38
  v_ProductOld NUMBER;
carlos@0
    39
  -- Parameter
carlos@0
    40
  TYPE RECORD IS REF CURSOR;
carlos@0
    41
    Cur_Parameter RECORD;
carlos@0
    42
    Cur_InOutLine RECORD;
carlos@0
    43
    Cur_ProdCost RECORD;
carlos@0
    44
    Cur_PriceList RECORD;
carlos@0
    45
    v_rowcount NUMBER;
carlos@0
    46
  BEGIN
carlos@0
    47
    v_Qty:=0;
carlos@0
    48
    v_Cost:=0;
carlos@0
    49
    v_Price:=0;
carlos@0
    50
    v_CumQty:=0;
carlos@0
    51
    v_ProductOld:=0;
carlos@0
    52
    --  Update AD_PInstance
carlos@0
    53
    DBMS_OUTPUT.PUT_LINE('Updating PInstance - Processing ' || p_PInstance_ID) ;
carlos@0
    54
    v_ResultStr:='PInstanceNotFound';
carlos@0
    55
    AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'Y', NULL, NULL) ;
carlos@0
    56
  BEGIN --BODY
carlos@0
    57
    --  Get Parameters
carlos@0
    58
    v_ResultStr:='ReadingParameters';
carlos@0
    59
    FOR Cur_Parameter IN
carlos@0
    60
      (SELECT i.Record_ID,
carlos@0
    61
        i.AD_User_ID,
carlos@0
    62
        p.ParameterName,
carlos@0
    63
        p.P_String,
carlos@0
    64
        p.P_Number,
carlos@0
    65
        p.P_Date
carlos@0
    66
      FROM AD_PInstance i
carlos@0
    67
      LEFT JOIN AD_PInstance_Para p
carlos@0
    68
        ON i.AD_PInstance_ID=p.AD_PInstance_ID
carlos@0
    69
      WHERE i.AD_PInstance_ID=p_PInstance_ID
carlos@0
    70
      ORDER BY p.SeqNo
carlos@0
    71
      )
carlos@0
    72
    LOOP
carlos@0
    73
      v_Record_ID:=Cur_Parameter.Record_ID;
carlos@0
    74
      v_User:=Cur_Parameter.AD_User_ID;
carlos@0
    75
    END LOOP; --  Get Parameter
carlos@0
    76
    DELETE
carlos@0
    77
    FROM M_COSTING
carlos@0
    78
    WHERE ISPERMANENT='N'
carlos@0
    79
      AND ISMANUAL='N'
gorkaion@591
    80
      AND COSTTYPE='AV'
gorkaion@591
    81
      AND ISPRODUCTION = 'N';
carlos@0
    82
    v_rowcount:=SQL%ROWCOUNT;
carlos@0
    83
    v_Deleted:=v_Deleted + v_rowcount;
carlos@0
    84
    v_rowcount:=SQL%ROWCOUNT;
carlos@0
    85
    DBMS_OUTPUT.PUT_LINE('  deleted=' || v_rowcount) ;
carlos@0
    86
    v_DateOld:=TO_DATE('01-01-1900', 'DD-MM-YYYY') ;
carlos@0
    87
    FOR Cur_InOutLine IN
carlos@0
    88
      (SELECT M_INOUTLINE.M_INOUTLINE_ID, M_INOUTLINE.MOVEMENTQTY, M_PRODUCT.M_PRODUCT_ID, M_INOUT.MOVEMENTDATE,
carlos@0
    89
        M_INOUTLINE.AD_CLIENT_ID, M_INOUTLINE.AD_ORG_ID, M_INOUT.C_BPARTNER_ID
carlos@0
    90
      FROM M_INOUT, M_INOUTLINE, M_PRODUCT
carlos@0
    91
      WHERE M_INOUT.M_INOUT_ID=M_INOUTLINE.M_INOUT_ID
carlos@0
    92
        AND M_INOUTLINE.M_PRODUCT_ID=M_PRODUCT.M_PRODUCT_ID
carlos@0
    93
        AND M_PRODUCT.COSTTYPE='AV'
carlos@0
    94
        AND M_INOUT.ISSOTRX='N'
carlos@0
    95
        AND M_INOUT.PROCESSED='Y'
gorkaion@239
    96
        AND M_INOUTLINE.MOVEMENTQTY>0
gorkaion@591
    97
        AND M_INOUT.DOCSTATUS <> 'DR' AND M_INOUT.DOCSTATUS <> 'RE'
carlos@0
    98
        AND NOT EXISTS
carlos@0
    99
        (SELECT 1 FROM M_COSTING WHERE M_INOUTLINE_ID=M_INOUTLINE.M_INOUTLINE_ID)
carlos@0
   100
      ORDER BY M_PRODUCT.M_PRODUCT_ID, M_INOUT.MOVEMENTDATE, M_INOUTLINE.MOVEMENTQTY DESC
carlos@0
   101
      )
carlos@0
   102
    LOOP
gorkaion@591
   103
      v_ResultStr:='new albaran:   '||Cur_InOutLine.M_INOUTLINE_ID;
gorkaion@239
   104
      IF(Cur_InOutLine.MOVEMENTDATE<>v_DateOld OR Cur_InOutLine.M_PRODUCT_ID<>v_ProductOld) THEN
carlos@0
   105
        v_CumQty:=0;
carlos@0
   106
      END IF;
carlos@0
   107
      SELECT COUNT(*)
carlos@0
   108
      INTO v_Count
carlos@0
   109
      FROM M_COSTING
carlos@0
   110
      WHERE M_PRODUCT_ID=Cur_InOutLine.M_PRODUCT_ID;
gorkaion@239
   111
      IF(v_Count>0) THEN
carlos@0
   112
        FOR Cur_ProdCost IN
gorkaion@591
   113
          (SELECT COST, DATETO, M_COSTING_ID
carlos@0
   114
          FROM M_COSTING
carlos@0
   115
          WHERE M_PRODUCT_ID=Cur_InOutLine.M_PRODUCT_ID
gorkaion@591
   116
            AND DATEFROM <= Cur_InOutLine.MOVEMENTDATE
carlos@0
   117
          ORDER BY DATETO DESC, M_COSTING_ID
carlos@0
   118
          )
carlos@0
   119
        LOOP
carlos@0
   120
          v_Cost:=Cur_ProdCost.COST;
gorkaion@591
   121
          v_Date:=Cur_ProdCost.DATETO;
gorkaion@591
   122
          UPDATE M_COSTING
gorkaion@591
   123
          SET DATETO = Cur_InOutLine.MOVEMENTDATE
gorkaion@591
   124
          WHERE M_COSTING_ID = Cur_ProdCost.M_COSTING_ID;
carlos@0
   125
          EXIT;
carlos@0
   126
        END LOOP;
carlos@0
   127
      ELSE
carlos@0
   128
        v_Cost:=NULL;
gorkaion@591
   129
        v_Date := TO_DATE('31-12-9999', 'DD-MM-YYYY');
carlos@0
   130
      END IF;
carlos@0
   131
      IF(v_Cost IS NOT NULL) THEN
carlos@0
   132
        SELECT COALESCE(SUM(MOVEMENTQTY), 0)
carlos@0
   133
        INTO v_Qty
carlos@0
   134
        FROM M_TRANSACTION
carlos@0
   135
        WHERE M_PRODUCT_ID=Cur_InOutLine.M_PRODUCT_ID
gorkaion@239
   136
          AND MOVEMENTDATE<Cur_InOutLine.MOVEMENTDATE;
carlos@0
   137
      ELSE
carlos@0
   138
        v_Qty:=0;
carlos@0
   139
      END IF;
gorkaion@591
   140
      v_ResultStr:='invoice albaran:   '||Cur_InOutLine.M_INOUTLINE_ID;
gorkaion@239
   141
      SELECT CASE WHEN SUM(QTYINVOICED) <=0 THEN 0 ELSE SUM(C_INVOICELINE.QTYINVOICED*C_INVOICELINE.PRICEACTUAL) /SUM(QTYINVOICED) END,
gorkaion@591
   142
             CASE WHEN SUM(QTYINVOICED) <=0 THEN 0 ELSE COUNT(C_INVOICELINE.C_INVOICELINE_ID) END
carlos@0
   143
      INTO v_Price, v_Count
carlos@0
   144
      FROM M_MATCHINV, C_INVOICELINE
carlos@0
   145
      WHERE M_MATCHINV.C_INVOICELINE_ID=C_INVOICELINE.C_INVOICELINE_ID
carlos@0
   146
        AND M_MATCHINV.M_INOUTLINE_ID=Cur_InOutLine.M_INOUTLINE_ID
gorkaion@239
   147
        AND QTYINVOICED<>0;
carlos@0
   148
      IF(v_Count=0) THEN
carlos@0
   149
        v_ResultStr:='order albaran:   '||Cur_InOutLine.M_INOUTLINE_ID;
gorkaion@591
   150
        SELECT CASE WHEN SUM(C_ORDERLINE.QTYORDERED) <=0 THEN 0 ELSE SUM(C_ORDERLINE.QTYORDERED*C_ORDERLINE.PRICEACTUAL) /SUM(C_ORDERLINE.QTYORDERED) END,
gorkaion@591
   151
               CASE WHEN SUM(C_ORDERLINE.QTYORDERED) <=0 THEN 0 ELSE COUNT(C_ORDERLINE.C_ORDERLINE_ID) END
carlos@0
   152
        INTO v_Price, v_Count
carlos@0
   153
        FROM M_MATCHPO, C_ORDERLINE
carlos@0
   154
        WHERE M_MATCHPO.C_ORDERLINE_ID=C_ORDERLINE.C_ORDERLINE_ID
carlos@0
   155
          AND M_MATCHPO.C_INVOICELINE_ID IS NULL
carlos@0
   156
          AND M_MATCHPO.M_INOUTLINE_ID=Cur_InOutLine.M_INOUTLINE_ID
gorkaion@239
   157
          AND C_ORDERLINE.QTYORDERED<>0;
carlos@0
   158
carlos@0
   159
      END IF;
carlos@0
   160
      IF(v_Count=0) THEN
carlos@0
   161
        FOR Cur_PriceList IN
carlos@0
   162
          (SELECT M_PRODUCTPRICE.PRICESTD
carlos@0
   163
          FROM M_PRICELIST_VERSION, M_PRODUCTPRICE
carlos@0
   164
          WHERE M_PRICELIST_VERSION.M_PRICELIST_ID=
carlos@0
   165
            (SELECT po_pricelist_id
carlos@0
   166
            FROM C_BPARTNER
carlos@0
   167
            WHERE c_bpartner_id=Cur_InOutLine.C_BPARTNER_ID
carlos@0
   168
            )
carlos@0
   169
            AND M_PRICELIST_VERSION.M_PRICELIST_VERSION_ID=M_PRODUCTPRICE.M_PRICELIST_VERSION_ID
carlos@0
   170
            AND M_PRICELIST_VERSION.ISACTIVE='Y'
carlos@0
   171
            AND M_PRODUCTPRICE.M_PRODUCT_ID=Cur_InOutLine.M_PRODUCT_ID
gorkaion@239
   172
            AND M_PRICELIST_VERSION.VALIDFROM<Cur_InOutLine.MOVEMENTDATE
carlos@0
   173
          ORDER BY M_PRICELIST_VERSION.VALIDFROM DESC
carlos@0
   174
          )
carlos@0
   175
        LOOP
carlos@0
   176
          v_Price:=Cur_PriceList.PRICESTD;
carlos@0
   177
          EXIT;
carlos@0
   178
        END LOOP;
carlos@0
   179
      END IF;
gorkaion@591
   180
      v_ResultStr:='insert costing:   '||Cur_InOutLine.M_INOUTLINE_ID;
carlos@0
   181
      INSERT
carlos@0
   182
      INTO M_COSTING
carlos@0
   183
        (
carlos@0
   184
          M_COSTING_ID, CREATED, CREATEDBY, UPDATED,
carlos@0
   185
          UPDATEDBY, AD_CLIENT_ID, AD_ORG_ID, M_PRODUCT_ID,
carlos@0
   186
          DATETO, DATEFROM, ISMANUAL, M_INOUTLINE_ID,
carlos@0
   187
          C_INVOICELINE_ID, QTY, PRICE, CUMQTY,
carlos@0
   188
          COST, COSTTYPE, ISPERMANENT
carlos@0
   189
        )
carlos@0
   190
        VALUES
carlos@0
   191
        (
carlos@0
   192
          Ad_Sequence_Nextno('M_Costing'), now(), v_User, now(),
carlos@0
   193
          v_User, Cur_InOutLine.AD_CLIENT_ID, Cur_InOutLine.AD_ORG_ID, Cur_InOutLine.M_PRODUCT_ID,
gorkaion@591
   194
          v_Date, Cur_InOutLine.MOVEMENTDATE, 'N', Cur_InOutLine.M_INOUTLINE_ID,
carlos@0
   195
          NULL, Cur_InOutLine.MOVEMENTQTY, v_Price, COALESCE(v_Qty, 0) + Cur_InOutLine.MOVEMENTQTY + v_CumQty,(
carlos@0
   196
          CASE
gorkaion@239
   197
            WHEN v_Qty+v_CumQty<0 THEN v_Price
carlos@0
   198
            WHEN (v_Qty+Cur_InOutLine.MOVEMENTQTY+v_CumQty) = 0 THEN 0
carlos@0
   199
            ELSE (((v_Qty+v_CumQty)*COALESCE(v_Cost, v_Price)) +(Cur_InOutLine.MOVEMENTQTY *v_Price)) /(v_Qty+Cur_InOutLine.MOVEMENTQTY+v_CumQty) END),
carlos@0
   200
          'AV', 'N'
carlos@0
   201
        )
carlos@0
   202
        ;
carlos@0
   203
      IF(Cur_InOutLine.MOVEMENTDATE=v_DateOld AND Cur_InOutLine.M_PRODUCT_ID=v_ProductOld) THEN
carlos@0
   204
        v_CumQty:=v_CumQty + Cur_InOutLine.MOVEMENTQTY;
carlos@0
   205
      END IF;
carlos@0
   206
      v_DateOld:=Cur_InOutLine.MOVEMENTDATE;
carlos@0
   207
      v_ProductOld:=Cur_InOutLine.M_PRODUCT_ID;
carlos@0
   208
    END LOOP;
gorkaion@239
   209
    --<<FINISH_PROCESS>>
carlos@0
   210
    --  Update AD_PInstance
gorkaion@591
   211
    DBMS_OUTPUT.PUT_LINE('Updating PInstance - Finished ' || v_Message);
gorkaion@591
   212
    AD_UPDATE_PINSTANCE(p_PInstance_ID, v_User, 'N', 1, v_Message);
carlos@0
   213
    RETURN;
carlos@0
   214
  END; --BODY
carlos@0
   215
EXCEPTION
carlos@0
   216
WHEN OTHERS THEN
carlos@0
   217
  ROLLBACK;
gorkaion@591
   218
  DBMS_OUTPUT.PUT_LINE(v_ResultStr);
carlos@0
   219
  v_ResultStr:= '@ERROR=' || SQLERRM;
gorkaion@591
   220
  DBMS_OUTPUT.PUT_LINE(v_ResultStr);
gorkaion@591
   221
  AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'N', 0, v_ResultStr);
carlos@0
   222
  RETURN;
antonio@735
   223
END GENERATE_AVERAGE_COSTS
antonio@735
   224
]]></body>
adrian@94
   225
    </function>
adrian@94
   226
  </database>