src-db/database/model/functions/T_INVENTORYVALUE_CREATE.xml
changeset 799 fef2c5e2feb7
parent 798 4994e5a604bb
child 800 1ad8094b366f
equal deleted inserted replaced
798:4994e5a604bb 799:fef2c5e2feb7
     1 <?xml version="1.0"?>
       
     2   <database name="FUNCTION T_INVENTORYVALUE_CREATE">
       
     3     <function name="T_INVENTORYVALUE_CREATE" type="NULL">
       
     4       <parameter name="p_pinstance_id" type="NUMERIC" mode="in">
       
     5         <default/>
       
     6       </parameter>
       
     7       <body><![CDATA[/*************************************************************************
       
     8   * The contents of this file are subject to the Compiere Public
       
     9   * License 1.1 ("License"); You may not use this file except in
       
    10   * compliance with the License. You may obtain a copy of the License in
       
    11   * the legal folder of your Openbravo installation.
       
    12   * Software distributed under the License is distributed on an
       
    13   * "AS IS" basis, WITHOUT WARRANTY OF ANY KIND, either express or
       
    14   * implied. See the License for the specific language governing rights
       
    15   * and limitations under the License.
       
    16   * The Original Code is  Compiere  ERP &  Business Solution
       
    17   * The Initial Developer of the Original Code is Jorg Janke and ComPiere, Inc.
       
    18   * Portions created by Jorg Janke are Copyright (C) 1999-2001 Jorg Janke,
       
    19   * parts created by ComPiere are Copyright (C) ComPiere, Inc.;
       
    20   * All Rights Reserved.
       
    21   * Contributor(s): Openbravo SL
       
    22   * Contributions are Copyright (C) 2001-2008 Openbravo, S.L.
       
    23   *
       
    24   * Specifically, this derivative work is based upon the following Compiere
       
    25   * file and version.
       
    26   *************************************************************************
       
    27   * $Id: T_InventoryValue_Create.sql,v 1.6 2003/03/17 20:32:29 jjanke Exp $
       
    28   ***
       
    29   * Title: Inventory Valuation Temporary Table
       
    30   * Description:
       
    31   ************************************************************************/
       
    32   -- Logistice
       
    33   v_ResultStr VARCHAR2(2000):='';
       
    34   v_Message VARCHAR2(2000):='';
       
    35   v_Result NUMBER:=1; -- 0=failure
       
    36   v_Record_ID NUMBER;
       
    37   v_AD_User_ID NUMBER;
       
    38   -- Parameter
       
    39   TYPE RECORD IS REF CURSOR;
       
    40     Cur_Parameter RECORD;
       
    41     -- Parameter Variables
       
    42     v_M_PriceList_Version_ID NUMBER(10) ;
       
    43     v_DateValue DATE;
       
    44     v_M_Warehouse_ID NUMBER(10) ;
       
    45     v_C_Currency_ID NUMBER(10) ;
       
    46     FINISH_PROCESS BOOLEAN:=false;
       
    47     rowcount NUMBER;
       
    48   BEGIN
       
    49     --  Update AD_PInstance
       
    50     DBMS_OUTPUT.PUT_LINE('Updating PInstance - Processing ' || p_PInstance_ID) ;
       
    51     v_ResultStr:='PInstanceNotFound';
       
    52     AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'Y', NULL, NULL) ;
       
    53   BEGIN --BODY
       
    54     -- Get Parameters
       
    55     v_ResultStr:='ReadingParameters';
       
    56     FOR Cur_Parameter IN
       
    57       (SELECT i.Record_ID,
       
    58         i.AD_User_ID,
       
    59         p.ParameterName,
       
    60         p.P_String,
       
    61         p.P_Number,
       
    62         p.P_Date
       
    63       FROM AD_PInstance i
       
    64       LEFT JOIN AD_PInstance_Para p
       
    65         ON i.AD_PInstance_ID=p.AD_PInstance_ID
       
    66       WHERE i.AD_PInstance_ID=p_PInstance_ID
       
    67       ORDER BY p.SeqNo
       
    68       )
       
    69     LOOP
       
    70       v_Record_ID:=Cur_Parameter.Record_ID;
       
    71       v_AD_User_ID:=Cur_Parameter.AD_User_ID;
       
    72       IF(Cur_Parameter.ParameterName='M_PriceList_Version_ID') THEN
       
    73         v_M_PriceList_Version_ID:=Cur_Parameter.P_Number;
       
    74         DBMS_OUTPUT.PUT_LINE('  M_PriceList_Version_ID=' || v_M_PriceList_Version_ID) ;
       
    75       ELSIF(Cur_Parameter.ParameterName='DateValue') THEN
       
    76         v_DateValue:=Cur_Parameter.P_Date;
       
    77         DBMS_OUTPUT.PUT_LINE('  DateValue=' || v_DateValue) ;
       
    78       ELSIF(Cur_Parameter.ParameterName='M_Warehouse_ID') THEN
       
    79         v_M_Warehouse_ID:=Cur_Parameter.P_Number;
       
    80         DBMS_OUTPUT.PUT_LINE('  M_Warehouse_ID=' || v_M_Warehouse_ID) ;
       
    81       ELSIF(Cur_Parameter.ParameterName='C_Currency_ID') THEN
       
    82         v_C_Currency_ID:=Cur_Parameter.P_Number;
       
    83         DBMS_OUTPUT.PUT_LINE('  C_Currency_ID=' || v_C_Currency_ID) ;
       
    84       ELSE
       
    85         DBMS_OUTPUT.PUT_LINE('*** Unknown Parameter=' || Cur_Parameter.ParameterName) ;
       
    86       END IF;
       
    87     END LOOP; -- Get Parameter
       
    88     DBMS_OUTPUT.PUT_LINE('  Record_ID=' || v_Record_ID) ;
       
    89     -- Clear
       
    90     -- v_ResultStr := 'ClearTable';
       
    91     -- DELETE FROM T_InventoryValue WHERE M_Warehouse_ID=v_M_Warehouse_ID;
       
    92     -- COMMIT;
       
    93     -- Insert Products
       
    94     v_ResultStr:='InsertStockedProducts';
       
    95     INSERT
       
    96     INTO T_InventoryValue
       
    97       (
       
    98         AD_Client_ID,
       
    99         AD_Org_ID,
       
   100         AD_PInstance_ID,
       
   101         M_Warehouse_ID,
       
   102         M_Product_ID
       
   103       )
       
   104     SELECT AD_Client_ID,
       
   105       AD_Org_ID,
       
   106       p_PInstance_ID,
       
   107       v_M_Warehouse_ID,
       
   108       M_Product_ID
       
   109     FROM M_Product
       
   110     WHERE IsStocked='Y';
       
   111     --
       
   112     rowcount:=SQL%ROWCOUNT;
       
   113     IF(rowcount=0) THEN
       
   114       v_Message:='@Created@ = 0';
       
   115       FINISH_PROCESS:=true;
       
   116     END IF;
       
   117     IF(NOT FINISH_PROCESS) THEN
       
   118       -- Update Constants
       
   119       v_ResultStr:='UpdateConstants';
       
   120       UPDATE T_InventoryValue
       
   121         SET DateValue=TRUNC(v_DateValue) + 0.9993,
       
   122         M_PriceList_Version_ID=v_M_PriceList_Version_ID,
       
   123         C_Currency_ID=v_C_Currency_ID
       
   124       WHERE M_Warehouse_ID=v_M_Warehouse_ID;
       
   125       -- Get current QtyOnHand
       
   126       v_ResultStr:='GetQtyOnHand';
       
   127       UPDATE T_InventoryValue
       
   128         SET QtyOnHand=
       
   129         (SELECT SUM(QtyOnHand)
       
   130         FROM M_Storage_Detail s,
       
   131           M_Locator l
       
   132         WHERE T_InventoryValue.M_Product_ID=s.M_Product_ID
       
   133           AND l.M_Locator_ID=s.M_Locator_ID
       
   134           AND l.M_Warehouse_ID=T_InventoryValue.M_Warehouse_ID
       
   135         )
       
   136       WHERE T_InventoryValue.M_Warehouse_ID=v_M_Warehouse_ID;
       
   137       -- Adjust for Valuation Date
       
   138       v_ResultStr:='AdjustQtyOnHand';
       
   139       UPDATE T_InventoryValue
       
   140         SET QtyOnHand=
       
   141         (SELECT T_InventoryValue.QtyOnHand - COALESCE(SUM(t.MovementQty), 0)
       
   142         FROM M_Transaction t,
       
   143           M_Locator l
       
   144         WHERE t.M_Product_ID=T_InventoryValue.M_Product_ID  --            AND t.M_AttributeSetInstance_ID=T_InventoryValue.M_AttributeSetInstance_ID
       
   145           AND t.MovementDate>T_InventoryValue.DateValue
       
   146           AND t.M_Locator_ID=l.M_Locator_ID
       
   147           AND l.M_Warehouse_ID=T_InventoryValue.M_Warehouse_ID
       
   148         )
       
   149       WHERE T_InventoryValue.M_Warehouse_ID=v_M_Warehouse_ID;
       
   150       -- Delete Records w/o OnHand Qty
       
   151       v_ResultStr:='DeleteZeroQtyOnHand';
       
   152       DELETE FROM T_InventoryValue  WHERE QtyOnHand=0  OR QtyOnHand IS NULL;
       
   153       -- Update Prices
       
   154       v_ResultStr:='GetPrices';
       
   155       UPDATE T_InventoryValue
       
   156         SET PricePO=
       
   157         (SELECT C_Currency_Convert(po.PriceList, po.C_Currency_ID, T_InventoryValue.C_Currency_ID, T_InventoryValue.DateValue, null, T_InventoryValue.AD_Client_ID, T_InventoryValue.AD_Org_ID)
       
   158         FROM M_Product_PO po
       
   159         WHERE po.M_Product_ID=T_InventoryValue.M_Product_ID
       
   160           AND po.IsCurrentVendor='Y'
       
   161           AND po.M_Product_ID=
       
   162           (SELECT MAX(M_Product_PO.M_Product_ID)
       
   163           FROM M_Product_PO
       
   164           WHERE M_Product_PO.M_Product_ID=T_InventoryValue.M_Product_ID
       
   165             AND M_Product_PO.IsCurrentVendor='Y'
       
   166           )
       
   167         )
       
   168         ,
       
   169         PriceList=
       
   170         (SELECT C_Currency_Convert(pp.PriceList, pl.C_Currency_ID, T_InventoryValue.C_Currency_ID, T_InventoryValue.DateValue, null, T_InventoryValue.AD_Client_ID, T_InventoryValue.AD_Org_ID)
       
   171         FROM M_PriceList pl,
       
   172           M_PriceList_Version plv,
       
   173           M_ProductPrice pp
       
   174         WHERE pp.M_Product_ID=T_InventoryValue.M_Product_ID
       
   175           AND pp.M_PriceList_Version_ID=T_InventoryValue.M_PriceList_Version_ID
       
   176           AND pp.M_PriceList_Version_ID=plv.M_PriceList_Version_ID
       
   177           AND plv.M_PriceList_ID=pl.M_PriceList_ID
       
   178         )
       
   179         ,
       
   180         PriceStd=
       
   181         (SELECT C_Currency_Convert(pp.PriceStd, pl.C_Currency_ID, T_InventoryValue.C_Currency_ID, T_InventoryValue.DateValue, null, T_InventoryValue.AD_Client_ID, T_InventoryValue.AD_Org_ID)
       
   182         FROM M_PriceList pl,
       
   183           M_PriceList_Version plv,
       
   184           M_ProductPrice pp
       
   185         WHERE pp.M_Product_ID=T_InventoryValue.M_Product_ID
       
   186           AND pp.M_PriceList_Version_ID=T_InventoryValue.M_PriceList_Version_ID
       
   187           AND pp.M_PriceList_Version_ID=plv.M_PriceList_Version_ID
       
   188           AND plv.M_PriceList_ID=pl.M_PriceList_ID
       
   189         )
       
   190         ,
       
   191         PriceLimit=
       
   192         (SELECT C_Currency_Convert(pp.PriceLimit, pl.C_Currency_ID, T_InventoryValue.C_Currency_ID, T_InventoryValue.DateValue, null, T_InventoryValue.AD_Client_ID, T_InventoryValue.AD_Org_ID)
       
   193         FROM M_PriceList pl,
       
   194           M_PriceList_Version plv,
       
   195           M_ProductPrice pp
       
   196         WHERE pp.M_Product_ID=T_InventoryValue.M_Product_ID
       
   197           AND pp.M_PriceList_Version_ID=T_InventoryValue.M_PriceList_Version_ID
       
   198           AND pp.M_PriceList_Version_ID=plv.M_PriceList_Version_ID
       
   199           AND plv.M_PriceList_ID=pl.M_PriceList_ID
       
   200         )
       
   201         ,
       
   202         CostStandard=
       
   203         (SELECT C_Currency_Convert(pc.CurrentCostPrice, acs.C_Currency_ID, T_InventoryValue.C_Currency_ID, T_InventoryValue.DateValue, null, T_InventoryValue.AD_Client_ID, T_InventoryValue.AD_Org_ID)
       
   204         FROM AD_ClientInfo ci,
       
   205           C_AcctSchema acs,
       
   206           M_Product_Costing pc
       
   207         WHERE T_InventoryValue.AD_Client_ID=ci.AD_Client_ID
       
   208           AND ci.C_AcctSchema1_ID=acs.C_AcctSchema_ID
       
   209           AND acs.C_AcctSchema_ID=pc.C_AcctSchema_ID
       
   210           AND T_InventoryValue.M_Product_ID=pc.M_Product_ID
       
   211         )
       
   212       WHERE T_InventoryValue.M_Warehouse_ID=v_M_Warehouse_ID;
       
   213       -- Update Values
       
   214       v_ResultStr:='UpdateValue';
       
   215       UPDATE T_InventoryValue
       
   216         SET PricePOAmt=QtyOnHand * PricePO,
       
   217         PriceListAmt=QtyOnHand * PriceList,
       
   218         PriceStdAmt=QtyOnHand * PriceStd,
       
   219         PriceLimitAmt=QtyOnHand * PriceLimit,
       
   220         CostStandardAmt=QtyOnHand * CostStandard
       
   221       WHERE M_Warehouse_ID=v_M_Warehouse_ID;
       
   222       rowcount:=SQL%ROWCOUNT;
       
   223       v_Message:='@Created@ = ' || rowcount;
       
   224     END IF;--FINISH_PROCESS
       
   225     --<<FINISH_PROCESS>>
       
   226     --  Update AD_PInstance
       
   227     DBMS_OUTPUT.PUT_LINE('Updating PInstance - Finished ' || v_Message) ;
       
   228     AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'N', v_Result, v_Message) ;
       
   229     RETURN;
       
   230   END; --BODY
       
   231 EXCEPTION
       
   232 WHEN OTHERS THEN
       
   233    v_ResultStr:= '@ERROR=' || SQLERRM;
       
   234   DBMS_OUTPUT.PUT_LINE(v_ResultStr) ;
       
   235   ROLLBACK;
       
   236   AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'N', 0, v_ResultStr) ;
       
   237   RETURN;
       
   238 END T_INVENTORYVALUE_CREATE
       
   239 ]]></body>
       
   240     </function>
       
   241   </database>