src-db/database/model/functions/GENERATEPOFROMPROJECT.xml
author Asier Lostalé <asier.lostale@openbravo.com>
Mon, 05 May 2008 06:59:24 +0000
changeset 799 fef2c5e2feb7
parent 756 ae11e4610537
child 1535 df3c4c5c3d0d
permissions -rw-r--r--
Merged cleanup branch (r3931) with trunk
<?xml version="1.0"?>
  <database name="FUNCTION GENERATEPOFROMPROJECT">
    <function name="GENERATEPOFROMPROJECT" type="NULL">
      <parameter name="p_pinstance_id" type="NUMERIC" mode="in">
        <default/>
      </parameter>
      <body><![CDATA[/*************************************************************************
* The contents of this file are subject to the Openbravo  Public  License
* Version  1.0  (the  "License"),  being   the  Mozilla   Public  License
* Version 1.1  with a permitted attribution clause; you may not  use this
* file except in compliance with the License. You  may  obtain  a copy of
* the License at http://www.openbravo.com/legal/license.html
* Software distributed under the License  is  distributed  on  an "AS IS"
* basis, WITHOUT WARRANTY OF ANY KIND, either express or implied. See the
* License for the specific  language  governing  rights  and  limitations
* under the License.
* The Original Code is Openbravo ERP.
* The Initial Developer of the Original Code is Openbravo SL
* All portions are Copyright (C) 2001-2008 Openbravo SL
* All Rights Reserved.
* Contributor(s):  ______________________________________.
************************************************************************/
  v_ResultStr VARCHAR2(2000):='';
  v_Message VARCHAR2(2000):='';
  v_Result NUMBER:=1; -- 0=failure
  v_Record_ID NUMBER;
  v_AD_User_ID NUMBER;
  TYPE RECORD IS REF CURSOR;
    Cur_Parameter RECORD;
    v_C_Order_ID NUMBER;
    v_C_OrderLine_ID NUMBER;
    v_C_DOCTYPE_ID NUMBER;
    v_DocumentNo NVARCHAR2(30) ;
  BEGIN
    --  Update AD_PInstance
    DBMS_OUTPUT.PUT_LINE('Updating PInstance - Processing ' || p_PInstance_ID) ;
    v_ResultStr:='PInstanceNotFound';
    AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'Y', NULL, NULL) ;
  BEGIN --BODY
    -- Get PARAMETERS
    v_ResultStr:='ReadingParameters';
    FOR Cur_Parameter IN
      (SELECT i.Record_ID,
        i.AD_User_ID,
        i.AD_Client_ID,
        i.AD_Org_ID,
        p.ParameterName,
        p.P_String,
        p.P_Number,
        p.P_Date,
        p.P_Date_To
      FROM AD_PInstance i
      LEFT JOIN AD_PInstance_Para p
        ON i.AD_PInstance_ID=p.AD_PInstance_ID
      WHERE i.AD_PInstance_ID=p_PInstance_ID
      ORDER BY p.SeqNo
      )
    LOOP
      v_Record_ID:=Cur_Parameter.Record_ID;
      v_AD_User_ID:=Cur_Parameter.AD_User_ID;
    END LOOP; -- Get Parameter
    DBMS_OUTPUT.PUT_LINE('  Record_ID=' || v_Record_ID) ;
    DECLARE
      v_BPartner_Location_ID NUMBER;
      v_BillTo_ID NUMBER;
      v_Size NUMBER;
      v_UOM NUMBER;
      v_PriceStd NUMBER;
      v_PriceList NUMBER;
      v_PriceLimit NUMBER;
      v_C_UOM_ID NUMBER;
      v_C_Currency_ID NUMBER;
      v_PriceActual NUMBER;
      v_Discount NUMBER;
      v_Tax_ID NUMBER;
      v_M_PriceList_Version_ID NUMBER;

    TYPE RECORD IS REF CURSOR;
      Cur_SO RECORD;
      Cur_SOLINES RECORD;
    BEGIN
      v_ResultStr:='StartLoop';
      FOR Cur_SO IN
        (SELECT P.C_PROJECT_ID,
          P.PROJECTSTATUS,
          V.AD_CLIENT_ID,
          V.AD_ORG_ID,
          V.C_BPARTNER_ID,
          V.C_INCOTERMS_ID,
          V.C_PROJECT_VENDOR_ID,
          V.INCOTERMS_DESCRIPTION,
          V.M_PRICELIST_VERSION_ID,
          V.M_PRICELIST_ID,
          P.C_CAMPAIGN_ID,
          PL.C_CURRENCY_ID,
          BP.PAYMENTRULEPO AS PAYMENTRULE,
          BP.PO_PAYMENTTERM_ID AS C_PAYMENTTERM_ID,
          P.M_WAREHOUSE_ID,
          P.POREFERENCE,
          P.SALESREP_ID,
          P.CREATETEMPPRICELIST,
          P.DESCRIPTION
        FROM C_PROJECT P,
          C_PROJECT_VENDOR V,
          C_BPARTNER BP,
          M_PRICELIST PL
        WHERE P.C_PROJECT_ID=V.C_PROJECT_ID
          AND V.C_BPARTNER_ID=BP.C_BPARTNER_ID
          AND V.M_PRICELIST_ID=PL.M_PRICELIST_ID
          AND V.ISACTIVE='Y'
          AND V.C_PROJECT_VENDOR_ID=v_Record_ID
        )
      LOOP
        -- Check that we have some restrictions
        v_ResultStr:='CheckRestriction';
        IF(Cur_SO.PROJECTSTATUS IS NULL OR Cur_SO.PROJECTSTATUS<>'OR') THEN
         RAISE_APPLICATION_ERROR(-20000, '@Invalidprojectstatus@'||'. '||' @ChangeToOrder@'||'.');
        ELSIF Cur_SO.C_BPARTNER_ID IS NULL THEN
          RAISE_APPLICATION_ERROR(-20000, '@NoprojectBusinesspartner@');
        ELSIF Cur_SO.C_PAYMENTTERM_ID IS NULL THEN
          RAISE_APPLICATION_ERROR(-20000, '@ThebusinessPartner@'||' '||' @PaymenttermNotdefined@'||'.');
        ELSIF Cur_SO.M_PRICELIST_ID IS NULL THEN
          RAISE_APPLICATION_ERROR(-20000, '@ThebusinessPartner@'||' '||' @PricelistNotdefined@'||'.');
        ELSIF Cur_SO.C_CURRENCY_ID IS NULL THEN
          RAISE_APPLICATION_ERROR(-20000, '@ProjectCurrencyNotFound@'||'.');
        ELSIF Cur_SO.M_WAREHOUSE_ID IS NULL THEN
          RAISE_APPLICATION_ERROR(-20000, '@ProjectWarehouseNotFound@'||'.');
        ELSIF Cur_SO.SALESREP_ID IS NULL THEN
          RAISE_APPLICATION_ERROR(-20000, '@ProjectSalesRepNotFound@'||'.');
        END IF;

        v_C_DOCTYPE_ID:=Ad_Get_DocType(Cur_SO.AD_Client_ID, Cur_SO.AD_Org_ID, 'POO') ;
        AD_Sequence_DocType(v_C_DOCTYPE_ID, Cur_SO.AD_Client_ID, 'Y', v_DocumentNo) ;
        IF(v_DocumentNo IS NULL) THEN
          AD_Sequence_Doc('DocumentNo_C_Order', Cur_SO.AD_Client_ID, 'Y', v_DocumentNo) ;
        END IF;

        -- Get Business Partner Ship Location
        v_BPartner_Location_ID := C_GetBPLocationID(Cur_SO.C_BPartner_ID, 'S') ;
        IF (v_BPartner_Location_ID IS NULL) THEN
          RAISE_APPLICATION_ERROR(-20000, '@ThebusinessPartner@'||' '||' @ShiptoNotdefined@'||'.');
        END IF;

        -- Get Business Partner Bill Location
        v_Billto_ID := C_GetBPLocationID(Cur_SO.C_BPartner_ID, 'B') ;
        IF (v_Billto_ID IS NULL) THEN
          RAISE_APPLICATION_ERROR(-20000, '@ThebusinessPartner@'||' '||' @BillToNotdefined@'||'.');
        END IF;

        -- Get next C_Order_ID
        Ad_Sequence_Next('C_Order', Cur_SO.AD_CLIENT_ID, v_C_Order_ID) ;
        v_ResultStr:='C_ORDER_ID - ' || v_C_Order_ID;

        INSERT
        INTO C_ORDER
          (
            C_ORDER_ID, AD_CLIENT_ID, AD_ORG_ID, CREATEDBY,
            UPDATEDBY, ISSOTRX, DOCUMENTNO, DOCSTATUS,
            DOCACTION, C_DOCTYPE_ID, C_DOCTYPETARGET_ID, DATEORDERED,
            DATEACCT, C_BPARTNER_ID, C_BPARTNER_LOCATION_ID, ISDISCOUNTPRINTED,
            C_CURRENCY_ID, PAYMENTRULE, C_PAYMENTTERM_ID, INVOICERULE,
            DELIVERYRULE, FREIGHTCOSTRULE, DELIVERYVIARULE, PRIORITYRULE,
            TOTALLINES, GRANDTOTAL, M_WAREHOUSE_ID, M_PRICELIST_ID,
            ISTAXINCLUDED, POSTED, PROCESSING, SALESREP_ID,
            BILLTO_ID, POREFERENCE, C_CAMPAIGN_ID, C_PROJECT_ID,
            AD_USER_ID, COPYFROM, C_INCOTERMS_ID, INCOTERMSDESCRIPTION,
            DATEPROMISED, DESCRIPTION
          )
          VALUES
          (
            v_C_Order_ID, Cur_SO.AD_CLIENT_ID, Cur_SO.AD_ORG_ID, v_AD_User_ID,
            v_AD_User_ID, 'N', v_DocumentNo, 'DR',
             'CO', 0, v_C_DOCTYPE_ID, TRUNC(now(), 'DD'),
            TRUNC(now(), 'DD'), Cur_SO.C_BPARTNER_ID, v_BPartner_Location_ID, 'N',
            Cur_SO.C_CURRENCY_ID, COALESCE(Cur_SO.PAYMENTRULE, 'P'), Cur_SO.C_PAYMENTTERM_ID, 'D',
             'A', 'I', 'D', '5',
            0, 0, Cur_SO.M_WAREHOUSE_ID, Cur_SO.M_PRICELIST_ID,
             'N', 'N', 'N', Cur_SO.SALESREP_ID,
            v_BillTo_ID, Cur_SO.POREFERENCE, Cur_SO.C_CAMPAIGN_ID, Cur_SO.C_PROJECT_ID,
            NULL, 'N', Cur_SO.C_INCOTERMS_ID, Cur_SO.INCOTERMS_DESCRIPTION,
            TRUNC(now(), 'DD'), Cur_SO.DESCRIPTION
          )
          ;

        -- Select the price list version that a applies for the price list of the header
        SELECT Get_Pricelist_Version(Cur_SO.M_PriceList_ID, TRUNC(now(), 'DD'))
        INTO v_M_PriceList_Version_ID
        FROM DUAL;
        IF (v_M_PriceList_Version_ID IS NULL) THEN
          RAISE_APPLICATION_ERROR(-20000, '@PriceListVersionNotFound@'||'.');
        ELSE
         -- Select products, quantities, sequence numbers, descriptions and unit prices of the project
            -- In both cases, if no unit price has been defined for a product,
            -- price is taken from the price list of the project.
            -- And if no price is defined in the price list, price is set to 0.
          FOR Cur_SOLINES IN
            (
            SELECT pl.LINE AS SEQNO, pl.PRODUCT_DESCRIPTION AS DESCRIPTION, pl.M_PRODUCT_ID,
              pl.PLANNEDQTY AS QTY, pl.PLANNEDPOPRICE AS PRICEACTUAL, pl.C_TAX_ID
            FROM C_PROJECTLINE pl, C_PROJECT_VENDOR  pv
            WHERE pv.C_PROJECT_VENDOR_ID = v_Record_ID
              AND pl.C_PROJECT_ID = pv.C_PROJECT_ID
              AND pl.M_Product_ID IS NOT NULL
              AND pl.IsActive = 'Y'
            ORDER BY SEQNO ASC
            )
          LOOP

            -- Take StdPrice, PriceList and PriceLimit from Price List Version
            SELECT COUNT(*)
            INTO v_Size
            FROM M_PRODUCT p,M_PRODUCTPRICE pp,M_PRICELIST_VERSION pv,M_PRICELIST pl
            WHERE p.M_Product_ID=pp.M_Product_ID
              AND pp.M_PriceList_Version_ID=pv.M_PriceList_Version_ID
              AND pv.M_PriceList_ID=pl.M_PriceList_ID
              AND pv.IsActive='Y'
              AND p.M_Product_ID=Cur_SOLINES.M_PRODUCT_ID
              AND pv.M_PriceList_Version_ID=v_M_PriceList_Version_ID
              AND pl.C_Currency_ID=Cur_SO.C_CURRENCY_ID;
            IF (v_Size>0) THEN
              SELECT Bom_Pricestd(p.M_Product_ID, pv.M_PriceList_Version_ID) AS PriceStd,
                Bom_Pricelist(p.M_Product_ID, pv.M_PriceList_Version_ID) AS PriceList,
                Bom_Pricelimit(p.M_Product_ID, pv.M_PriceList_Version_ID) AS PriceLimit,
                p.C_UOM_ID
              INTO v_PriceStd,v_PriceList,
                v_PriceLimit,v_C_UOM_ID
              FROM M_PRODUCT p,M_PRODUCTPRICE pp,M_PRICELIST_VERSION pv,M_PRICELIST pl
              WHERE p.M_Product_ID=pp.M_Product_ID
                AND pp.M_PriceList_Version_ID=pv.M_PriceList_Version_ID
                AND pv.M_PriceList_ID=pl.M_PriceList_ID
                AND pv.IsActive='Y'
                AND p.M_Product_ID=Cur_SOLINES.M_PRODUCT_ID
                AND pv.M_PriceList_Version_ID=v_M_PriceList_Version_ID
                AND pl.C_Currency_ID=Cur_SO.C_CURRENCY_ID;
            ELSE
              v_PriceStd := NULL;
              v_PriceList := NULL;
              v_PriceLimit := NULL;
              v_C_UOM_ID := NULL;
            END IF;

            -- Calculate Price Actual
            IF (Cur_SOLINES.priceactual=0) THEN
              Cur_SOLINES.priceactual:=NULL;
            END IF;
            v_PriceActual := COALESCE(Cur_SOLINES.priceactual,M_Get_Offers_Price(now(), Cur_SO.C_BPARTNER_ID, Cur_SOLINES.M_PRODUCT_ID, v_PriceStd, Cur_SOLINES.Qty, Cur_SO.M_PRICELIST_ID),0);

            IF (v_PriceStd IS NULL) THEN
             v_PriceStd :=  v_PriceActual ;
            END IF;

            IF (v_PriceList IS NULL) THEN
              v_PriceList :=  v_PriceActual ;
            END IF;

            IF (v_PriceLimit IS NULL) THEN
              v_PriceLimit :=  v_PriceActual ;
            END IF;

            IF (v_PriceList = 0) THEN
               v_Discount := 0 ;
            ELSE
              -- Calculate rounded discount
              v_Discount :=ROUND((v_PriceList-v_PriceActual) / v_PriceList*100, 2);
            END IF;

            IF (v_C_UOM_ID IS NULL) THEN
              SELECT P.C_UOM_ID
              INTO v_UOM
              FROM M_PRODUCT P
              WHERE P.M_PRODUCT_ID=Cur_SOLINES.M_PRODUCT_ID;
            ELSE
              v_UOM := v_C_UOM_ID;
            END IF;

            IF (Cur_SOLINES.C_TAX_ID IS NULL) THEN
              v_Tax_ID:= C_Gettax(Cur_SOLINES.M_PRODUCT_ID, TRUNC(now(), 'DD'), Cur_SO.AD_ORG_ID, Cur_SO.M_WAREHOUSE_ID, v_BPartner_Location_ID, v_BPartner_Location_ID, Cur_SO.C_PROJECT_ID, 'Y') ;
            ELSE
              v_Tax_ID:=Cur_SOLINES.C_TAX_ID;
            END IF;

            -- Get next C_OrderLine_ID
            Ad_Sequence_Next('C_OrderLine', Cur_SO.AD_CLIENT_ID, v_C_OrderLine_ID) ;
            v_ResultStr:='C_OrderLine_ID - ' || v_C_OrderLine_ID;

            INSERT
            INTO C_ORDERLINE
              (
                DateOrdered, M_Warehouse_ID, QtyOrdered, QtyDelivered,
                QtyReserved, M_Shipper_ID, QtyInvoiced,
                C_Currency_ID, PriceList, DatePromised, DateDelivered,
                DateInvoiced, Created, IsActive, Line,
                C_OrderLine_ID, AD_Client_ID, C_Order_ID, Description,
                M_Product_ID, C_UOM_ID, DirectShip, CreatedBy,
                UpdatedBy, FreightAmt, C_Charge_ID, ChargeAmt,
                Updated, AD_Org_ID, S_ResourceAssignment_ID, C_BPartner_ID,
                PriceActual,
                C_Tax_ID, C_BPartner_Location_ID,
                Discount, PriceLimit, Ref_OrderLine_ID, LineNetAmt,
                M_AttributeSetInstance_ID, IsDescription, PriceStd
              )
              VALUES
              (
                TRUNC(now(), 'DD'), Cur_SO.M_WAREHOUSE_ID, Cur_SOLINES.Qty, 0,
                0, NULL, 0,
                Cur_SO.C_CURRENCY_ID, v_PriceList, TRUNC(now(), 'DD'), NULL,
                NULL, now(), 'Y', Cur_SOLINES.SEQNO,
                v_C_OrderLine_ID, Cur_SO.AD_CLIENT_ID, v_C_Order_ID, Cur_SOLINES.DESCRIPTION,
                Cur_SOLINES.M_PRODUCT_ID, v_UOM, 'N', v_AD_User_ID,
                v_AD_User_ID, 0, NULL, 0,
                now(), Cur_SO.AD_ORG_ID, NULL, Cur_SO.C_BPARTNER_ID,
                v_PriceActual,
                v_Tax_ID, v_BPartner_Location_ID,
                v_Discount, v_PriceLimit, NULL, v_PriceActual * Cur_SOLINES.Qty,
                NULL, 'N', v_PriceStd
              )
              ;
          END LOOP;
        END IF;

        IF v_Message IS NOT NULL THEN
          v_Message:=v_Message || ', ';
        END IF;
        v_Message:=v_Message || v_DocumentNo;
      END LOOP;
      v_Message:='@DocumentNo@: ' || v_Message;
    END;
    --<<FINISH_PROCESS>>
    --  Update AD_PInstance
    DBMS_OUTPUT.PUT_LINE('Updating PInstance - Finished ' || v_Message) ;
    AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'N', v_Result, v_Message) ;
    RETURN;
  END; --BODY
EXCEPTION
WHEN OTHERS THEN
  v_ResultStr:= '@ERROR=' || SQLERRM;
  DBMS_OUTPUT.PUT_LINE(v_ResultStr) ;
  ROLLBACK;
  AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'N', 0, v_ResultStr) ;
  RETURN;
END GENERATEPOFROMPROJECT
]]></body>
    </function>
  </database>