src-db/database/model/functions/MRP_PURCHASEORDER.xml
author Juan Pablo Aroztegi <juanpablo.aroztegi@openbravo.com>
Wed, 03 Sep 2008 17:55:37 +0000
changeset 1605 8a0fe0193bef
parent 756 ae11e4610537
child 2438 06ae8dda832b
permissions -rw-r--r--
Merge r2.5x intro trunk
carlos@0
     1
<?xml version="1.0"?>
adrian@94
     2
  <database name="FUNCTION MRP_PURCHASEORDER">
adrian@94
     3
    <function name="MRP_PURCHASEORDER" 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-2007 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_Message VARCHAR2(2000):='';
antonio@735
    26
  v_Result NUMBER:= 1;
juanpablo@1605
    27
  v_Record_ID VARCHAR2(32);
juanpablo@1605
    28
  v_User_ID VARCHAR2(32):='0';
juanpablo@1605
    29
  v_Client_ID VARCHAR2(32);
juanpablo@1605
    30
  v_Org_ID VARCHAR2(32);
carlos@0
    31
carlos@0
    32
juanpablo@1605
    33
  v_COrder_ID VARCHAR2(32);
juanpablo@1605
    34
  v_COrderLine_ID VARCHAR2(32);
carlos@0
    35
  v_DocumentNo NVARCHAR2(60);
carlos@0
    36
  v_created BOOLEAN := FALSE;
carlos@0
    37
  FINISH_PROCESS BOOLEAN DEFAULT FALSE;
carlos@0
    38
juanpablo@1605
    39
  v_M_Warehouse_ID VARCHAR2(32);
carlos@0
    40
  v_Description nvarchar2(255);
antonio@735
    41
  v_DateDoc DATE;
antonio@735
    42
  v_PriceList NUMBER;
antonio@735
    43
  v_PriceActual NUMBER;
antonio@735
    44
  v_PriceLimit NUMBER;
juanpablo@1605
    45
  LastCBPartner_ID VARCHAR2(32);
antonio@735
    46
  v_Line NUMBER;
juanpablo@1605
    47
  v_CDocTypeID varchar2(32);
juanpablo@1605
    48
  v_BPartner_Location_ID VARCHAR2(32);
juanpablo@1605
    49
  v_BillTo_ID VARCHAR2(32);
antonio@735
    50
  v_PriceListVersion NUMBER;
antonio@735
    51
  v_PriceStd NUMBER;
juanpablo@1605
    52
  v_TaxId varchar2(32);
carlos@0
    53
  v_ProductName NVARCHAR2(90);
carlos@0
    54
carlos@0
    55
  v_Count NUMBER;
carlos@0
    56
carlos@0
    57
carlos@0
    58
  --  Parameter
carlos@0
    59
  TYPE RECORD IS REF CURSOR;
carlos@0
    60
    Cur_Parameter RECORD;
carlos@0
    61
    Cur_workproposal RECORD;
carlos@0
    62
  BEGIN
carlos@0
    63
    DBMS_OUTPUT.PUT_LINE('Updating PInstance - Processing ' || p_PInstance_ID) ;
carlos@0
    64
    v_ResultStr:='PInstanceNotFound';
carlos@0
    65
    AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'Y', NULL, NULL) ;
carlos@0
    66
  BEGIN --BODY
carlos@0
    67
    -- Get Parameters
carlos@0
    68
    v_ResultStr:='ReadingParameters';
carlos@0
    69
    FOR Cur_Parameter IN
carlos@0
    70
      (SELECT i.Record_ID, i.AD_User_ID, i.AD_Client_ID, i.AD_Org_ID,
carlos@0
    71
        p.ParameterName, p.P_String, p.P_Number, p.P_Date
carlos@0
    72
      FROM AD_PInstance i
carlos@0
    73
      LEFT JOIN AD_PInstance_Para p
carlos@0
    74
        ON i.AD_PInstance_ID=p.AD_PInstance_ID
carlos@0
    75
      WHERE i.AD_PInstance_ID=p_PInstance_ID
carlos@0
    76
      ORDER BY p.SeqNo
carlos@0
    77
      )
carlos@0
    78
    LOOP
carlos@0
    79
      v_Record_ID:=Cur_Parameter.Record_ID;
carlos@0
    80
      v_User_ID:=Cur_Parameter.AD_User_ID;
carlos@0
    81
      v_Client_ID := Cur_Parameter.AD_Client_ID;
carlos@0
    82
      v_Org_ID := Cur_Parameter.AD_Org_ID;
carlos@0
    83
      IF(Cur_Parameter.ParameterName='M_Warehouse_ID') THEN
juanpablo@1605
    84
        v_M_Warehouse_ID:=Cur_Parameter.P_String;
carlos@0
    85
        DBMS_OUTPUT.PUT_LINE('  M_Warehouse_ID=' || v_M_Warehouse_ID);
carlos@0
    86
      END IF;
carlos@0
    87
    END LOOP; -- Get Parameter
carlos@0
    88
carlos@0
    89
    SELECT COALESCE(TO_CHAR(DESCRIPTION), ' '), DateDoc
carlos@0
    90
      INTO v_Description, v_DateDoc
carlos@0
    91
     FROM MRP_RUN_PURCHASE
carlos@0
    92
     WHERE MRP_RUN_PURCHASE_ID = v_Record_ID;
carlos@0
    93
carlos@0
    94
    FOR Cur_workproposal IN (
carlos@0
    95
      SELECT rp.*, bp.PO_PRICELIST_ID, pl.C_Currency_ID,
carlos@0
    96
             BP.PAYMENTRULEPO as paymentrule, BP.PO_PAYMENTTERM_ID AS C_PAYMENTTERM_ID,
carlos@0
    97
             bp.DeliveryViaRule, p.C_UOM_ID
carlos@0
    98
      FROM MRP_RUN_PURCHASELINE rp,
carlos@0
    99
           C_BPartner bp,
carlos@0
   100
           M_PriceList pl,
carlos@0
   101
           M_Product p
carlos@0
   102
      WHERE rp.MRP_RUN_PURCHASE_ID = v_Record_ID
carlos@0
   103
        AND INOUTTRXTYPE = 'PP'
carlos@0
   104
        AND rp.C_OrderLine_ID IS NULL
carlos@0
   105
        AND rp.C_Bpartner_ID = bp.C_BPartner_ID
carlos@0
   106
        AND pl.M_PriceList_ID = bp.PO_PRICELIST_ID
carlos@0
   107
        AND p.M_Product_ID = rp.M_Product_ID
carlos@0
   108
      ORDER BY rp.C_BPartner_ID, rp.PLANNEDDATE
carlos@0
   109
      ) LOOP
carlos@0
   110
      v_ResultStr:='Create Purchase Order';
carlos@0
   111
carlos@0
   112
      if (v_COrder_Id is null) or (Cur_workproposal.C_BPartner_ID!=LastCBPartner_ID) then --new header
carlos@0
   113
        v_Line := 0;
gorkaion@586
   114
        Ad_Sequence_Next('C_Order', v_Client_ID, v_COrder_ID);
carlos@0
   115
        Ad_Sequence_Doc('DocumentNo_C_Order', v_Client_ID, 'Y', v_DocumentNo);
carlos@0
   116
        v_CDocTypeID := AD_Get_DocType(v_Client_ID, v_Org_ID,'POO',NULL);
carlos@0
   117
carlos@0
   118
        SELECT MIN(C_BPARTNER_LOCATION_ID)
carlos@0
   119
        INTO v_BPartner_Location_ID
carlos@0
   120
        FROM C_BPARTNER_LOCATION
carlos@0
   121
        WHERE ISACTIVE='Y'
carlos@0
   122
          AND ISSHIPTO='Y'
carlos@0
   123
          AND C_BPARTNER_ID=Cur_workproposal.C_BPARTNER_ID;
carlos@0
   124
carlos@0
   125
        SELECT MIN(C_BPARTNER_LOCATION_ID)
carlos@0
   126
        INTO v_BillTo_ID
carlos@0
   127
        FROM C_BPARTNER_LOCATION
carlos@0
   128
        WHERE ISACTIVE='Y'
carlos@0
   129
          AND ISBILLTO='Y'
carlos@0
   130
          AND C_BPARTNER_ID=Cur_workproposal.C_BPARTNER_ID;
carlos@0
   131
carlos@0
   132
        INSERT INTO C_Order
carlos@0
   133
          (C_ORDER_ID, AD_CLIENT_ID, AD_ORG_ID, ISACTIVE,
carlos@0
   134
           CREATED, CREATEDBY, UPDATED, UPDATEDBY,
carlos@0
   135
           ISSOTRX, DOCUMENTNO, DOCSTATUS, DOCACTION,
carlos@0
   136
           C_DOCTYPE_ID,C_DOCTYPETARGET_ID, DESCRIPTION,
carlos@0
   137
           DATEORDERED, DATEACCT, C_BPARTNER_ID, BILLTO_ID,
carlos@0
   138
           C_BPARTNER_LOCATION_ID, C_CURRENCY_ID, PAYMENTRULE, C_PAYMENTTERM_ID,
carlos@0
   139
           INVOICERULE, DELIVERYRULE, FREIGHTCOSTRULE, DELIVERYVIARULE,
carlos@0
   140
           PRIORITYRULE, TOTALLINES, GRANDTOTAL,
carlos@0
   141
           M_WAREHOUSE_ID, M_PRICELIST_ID, ISTAXINCLUDED, DATEPROMISED)
carlos@0
   142
        VALUES
carlos@0
   143
         (v_COrder_ID, v_Client_ID, v_Org_ID,'Y',
carlos@0
   144
         now(), v_User_ID, now(), v_User_ID,
carlos@0
   145
         'N', v_DocumentNo,  'DR', 'CO',
carlos@0
   146
          v_CDocTypeID, v_CDocTypeID, v_Description,
carlos@0
   147
          v_DateDoc,v_DateDoc, Cur_workproposal.C_BPartner_ID,v_BillTo_ID,
carlos@0
   148
          v_BPartner_Location_ID, Cur_workproposal.C_Currency_ID, Cur_workproposal.paymentrule, Cur_workproposal.C_PAYMENTTERM_ID,
carlos@0
   149
          'D', 'A', 'I',COALESCE(Cur_workproposal.DeliveryViaRule,'D'),
carlos@0
   150
          '5',0,0,
carlos@0
   151
          v_M_Warehouse_ID, Cur_workproposal.PO_PRICELIST_ID, 'N', v_DateDoc
carlos@0
   152
          );
carlos@0
   153
      end if; --header
carlos@0
   154
      LastCBPartner_ID := Cur_workproposal.C_BPartner_ID;
carlos@0
   155
carlos@0
   156
      v_Line := v_Line + 10;
gorkaion@586
   157
      Ad_Sequence_Next('C_OrderLine', v_Client_ID, v_COrderLine_ID);
carlos@0
   158
carlos@0
   159
      v_ResultStr:='Get order line data';
carlos@0
   160
      SELECT count(*) INTO v_Count
carlos@0
   161
      FROM M_ProductPrice
carlos@0
   162
       WHERE M_Product_ID = Cur_workproposal.M_Product_ID
carlos@0
   163
         AND M_PRICELIST_VERSION_ID = (SELECT min(plv.M_PriceList_Version_ID) as M_PriceList_Version_ID
carlos@0
   164
        FROM M_PriceList_Version plv
carlos@0
   165
        WHERE plv.M_PriceList_ID = Cur_workproposal.PO_PRICELIST_ID
carlos@0
   166
        AND plv.IsActive= 'Y'
gorkaion@239
   167
        AND plv.ValidFrom <= v_DateDoc
carlos@0
   168
        AND plv.AD_Client_ID =v_Client_ID
carlos@0
   169
        AND ValidFrom = (SELECT max(ValidFrom)
carlos@0
   170
                          FROM M_PriceList pl, M_PriceList_Version plv
carlos@0
   171
                          WHERE pl.M_PriceList_ID=plv.M_PriceList_ID
carlos@0
   172
                          AND plv.IsActive= 'Y'
carlos@0
   173
                          AND pl.M_PriceList_ID = Cur_workproposal.PO_PRICELIST_ID
gorkaion@239
   174
                          AND plv.ValidFrom <= v_DateDoc
carlos@0
   175
                          AND plv.AD_Client_ID =v_Client_ID));
carlos@0
   176
gorkaion@239
   177
      IF (v_count > 0) THEN
carlos@0
   178
        SELECT PriceList, PriceStd,
carlos@0
   179
               M_Get_Offers_Price(v_DateDoc,Cur_workproposal.C_BPartner_ID,Cur_workproposal.M_Product_ID,PriceStd,Cur_workproposal.QTY, Cur_workproposal.PO_PRICELIST_ID),
carlos@0
   180
               PriceLimit
carlos@0
   181
          INTO v_PriceList, v_PriceStd, v_PriceActual, v_PriceLimit
carlos@0
   182
        FROM M_ProductPrice
carlos@0
   183
        WHERE M_Product_ID = Cur_workproposal.M_Product_ID
carlos@0
   184
          AND M_PRICELIST_VERSION_ID = (
carlos@0
   185
                SELECT min(plv.M_PriceList_Version_ID) as M_PriceList_Version_ID
carlos@0
   186
                FROM M_PriceList_Version plv
carlos@0
   187
                WHERE plv.M_PriceList_ID = Cur_workproposal.PO_PRICELIST_ID
carlos@0
   188
                  AND plv.IsActive= 'Y'
gorkaion@239
   189
                  AND plv.ValidFrom <= v_DateDoc
carlos@0
   190
                  AND plv.AD_Client_ID =v_Client_ID
carlos@0
   191
                  AND ValidFrom = (SELECT max(ValidFrom)
carlos@0
   192
                                  FROM M_PriceList pl, M_PriceList_Version plv
carlos@0
   193
                                  WHERE pl.M_PriceList_ID=plv.M_PriceList_ID
carlos@0
   194
                                    AND plv.IsActive= 'Y'
carlos@0
   195
                                    AND pl.M_PriceList_ID = Cur_workproposal.PO_PRICELIST_ID
gorkaion@239
   196
                                    AND plv.ValidFrom <= v_DateDoc
carlos@0
   197
                                    AND plv.AD_Client_ID =v_Client_ID));
carlos@0
   198
      ELSE
carlos@0
   199
        SELECT NAME INTO v_ProductName
carlos@0
   200
        FROM M_PRODUCT
carlos@0
   201
        WHERE M_PRODUCT_ID = Cur_workproposal.M_Product_ID;
carlos@0
   202
        v_Result := 0;
carlos@0
   203
        v_Message := '@PriceNotFound@ ' || v_ProductName;
carlos@0
   204
        RAISE_APPLICATION_ERROR(-20000, v_Message);
carlos@0
   205
      END IF;
carlos@0
   206
carlos@0
   207
      v_TaxID := C_GetTax(Cur_workproposal.M_Product_ID, v_DateDoc, v_Org_ID, v_M_Warehouse_ID, v_BillTo_ID, v_BPartner_Location_ID, null, 'N');
carlos@0
   208
carlos@0
   209
      v_ResultStr:='Insert order line';
carlos@0
   210
      INSERT INTO C_OrderLine
carlos@0
   211
        (C_ORDERLINE_ID, AD_CLIENT_ID, AD_ORG_ID, ISACTIVE,
carlos@0
   212
         CREATED, CREATEDBY, UPDATED, UPDATEDBY,
carlos@0
   213
         C_ORDER_ID, LINE, C_BPARTNER_ID, C_BPARTNER_LOCATION_ID,
carlos@0
   214
         DATEORDERED, DATEPROMISED, DESCRIPTION, M_PRODUCT_ID,
carlos@0
   215
         M_WAREHOUSE_ID, C_UOM_ID, QTYORDERED, C_CURRENCY_ID,
carlos@0
   216
         PRICELIST, PRICEACTUAL, PRICELIMIT,
carlos@0
   217
         PRICESTD, LINENETAMT, DISCOUNT,
carlos@0
   218
         C_TAX_ID)
carlos@0
   219
     VALUES
carlos@0
   220
      (v_COrderLine_ID,v_Client_ID, v_Org_ID,'Y',
carlos@0
   221
       now(), v_User_ID, now(), v_User_ID,
carlos@0
   222
       v_COrder_ID, v_Line, Cur_workproposal.C_BPartner_ID, v_BPartner_Location_ID,
carlos@0
   223
       Cur_workproposal.PLANNEDORDERDATE, Cur_workproposal.PLANNEDDATE, v_Description, Cur_workproposal.M_Product_ID,
carlos@0
   224
       v_M_Warehouse_ID, Cur_workproposal.C_UOM_ID, Cur_workproposal.QTY, Cur_workproposal.C_Currency_ID,
carlos@0
   225
       v_PriceList, v_PriceActual, v_PriceLimit,
carlos@0
   226
       v_PriceStd, v_PriceActual*Cur_workproposal.QTY,((v_PriceList-v_PriceStd) / (v_PriceList * 100)),
carlos@0
   227
       v_TaxID
carlos@0
   228
      );
carlos@0
   229
carlos@0
   230
      UPDATE MRP_RUN_PURCHASELINE
carlos@0
   231
        SET C_OrderLine_ID = v_COrderLine_ID
carlos@0
   232
      WHERE MRP_RUN_PURCHASELINE_ID = Cur_workproposal.MRP_RUN_PURCHASELINE_ID;
carlos@0
   233
carlos@0
   234
carlos@0
   235
carlos@0
   236
    END LOOP;
gorkaion@586
   237
  v_ResultStr :='Set requisition lines as planned';
antonio@737
   238
  UPDATE M_RequisitionLine
gorkaion@586
   239
  SET REQSTATUS = 'P'
gorkaion@586
   240
  WHERE M_RequisitionLine_ID IN (SELECT M_RequisitionLine_ID
gorkaion@586
   241
                                 FROM MRP_RUN_PURCHASELINE
gorkaion@586
   242
                                 WHERE MRP_RUN_PURCHASE_ID = v_Record_ID
gorkaion@586
   243
                                   AND INOUTTRXTYPE = 'MF');
antonio@737
   244
gorkaion@586
   245
  UPDATE M_Requisition
gorkaion@586
   246
  SET DocStatus = 'CL'
antonio@737
   247
  WHERE M_Requisition_ID IN (SELECT M_Requisition_ID
antonio@737
   248
                            FROM M_RequisitionLine
gorkaion@586
   249
                            WHERE M_RequisitionLine_ID IN (SELECT M_RequisitionLine_ID
gorkaion@586
   250
                                                          FROM MRP_RUN_PURCHASELINE
gorkaion@586
   251
                                                          WHERE MRP_RUN_PURCHASE_ID = v_Record_ID
gorkaion@586
   252
                                                            AND INOUTTRXTYPE = 'MF'))
gorkaion@586
   253
    AND NOT EXISTS (SELECT 1
gorkaion@586
   254
                    FROM M_RequisitionLine rl
gorkaion@586
   255
                    WHERE rl.REQSTATUS = 'O'
antonio@737
   256
                      AND rl.M_Requisition_ID = M_Requisition.M_Requisition_ID);
carlos@0
   257
  END;--BODY
carlos@0
   258
  IF(p_PInstance_ID IS NOT NULL) THEN
carlos@0
   259
    AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'N', v_Result, v_Message) ;
carlos@0
   260
  END IF;
carlos@0
   261
EXCEPTION
carlos@0
   262
WHEN OTHERS THEN
carlos@0
   263
  DBMS_OUTPUT.PUT_LINE('MRP_PURCHASEORDER exception: ' || v_ResultStr) ;
carlos@0
   264
  v_ResultStr:= '@ERROR=' || SQLERRM;
carlos@0
   265
  DBMS_OUTPUT.PUT_LINE(v_ResultStr) ;
carlos@0
   266
  ROLLBACK;
carlos@0
   267
  AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'N', 0, v_ResultStr) ;
carlos@0
   268
--  RETURN;
adrian@94
   269
END MRP_PURCHASEORDER
gorkaion@239
   270
]]></body>
adrian@94
   271
    </function>
adrian@94
   272
  </database>