src-db/database/model/functions/MRP_PURCHASEPLAN.xml
author Juan Pablo Aroztegi <juanpablo.aroztegi@openbravo.com>
Wed, 03 Sep 2008 17:55:37 +0000
changeset 1605 8a0fe0193bef
parent 1512 770d78feef7d
child 2586 683779f1e610
permissions -rw-r--r--
Merge r2.5x intro trunk
carlos@0
     1
<?xml version="1.0"?>
adrian@94
     2
  <database name="FUNCTION MRP_PURCHASEPLAN">
adrian@94
     3
    <function name="MRP_PURCHASEPLAN" type="NULL">
juanpablo@1605
     4
      <parameter name="p_user_id" type="VARCHAR" mode="in">
antonio@735
     5
        <default/>
antonio@735
     6
      </parameter>
juanpablo@1605
     7
      <parameter name="p_org_id" type="VARCHAR" mode="in">
antonio@735
     8
        <default/>
antonio@735
     9
      </parameter>
juanpablo@1605
    10
      <parameter name="p_client_id" type="VARCHAR" mode="in">
antonio@735
    11
        <default/>
antonio@735
    12
      </parameter>
juanpablo@1605
    13
      <parameter name="p_run_id" type="VARCHAR" mode="in">
antonio@735
    14
        <default/>
antonio@735
    15
      </parameter>
juanpablo@1605
    16
      <parameter name="p_planner_id" type="VARCHAR" mode="in">
antonio@735
    17
        <default/>
antonio@735
    18
      </parameter>
juanpablo@1605
    19
      <parameter name="p_vendor_id" type="VARCHAR" mode="in">
antonio@735
    20
        <default/>
antonio@735
    21
      </parameter>
antonio@735
    22
      <parameter name="p_timehorizon" type="NUMERIC" mode="in">
antonio@735
    23
        <default/>
antonio@735
    24
      </parameter>
antonio@735
    25
      <parameter name="p_planningdate" type="TIMESTAMP" mode="in">
antonio@735
    26
        <default/>
antonio@735
    27
      </parameter>
antonio@735
    28
      <parameter name="p_securitymargin" type="NUMERIC" mode="in">
antonio@735
    29
        <default/>
antonio@735
    30
      </parameter>
gorkaion@239
    31
      <body><![CDATA[/*************************************************************************
carlos@0
    32
* The contents of this file are subject to the Openbravo  Public  License
carlos@0
    33
* Version  1.0  (the  "License"),  being   the  Mozilla   Public  License
carlos@0
    34
* Version 1.1  with a permitted attribution clause; you may not  use this
carlos@0
    35
* file except in compliance with the License. You  may  obtain  a copy of
carlos@0
    36
* the License at http://www.openbravo.com/legal/license.html
carlos@0
    37
* Software distributed under the License  is  distributed  on  an "AS IS"
carlos@0
    38
* basis, WITHOUT WARRANTY OF ANY KIND, either express or implied. See the
carlos@0
    39
* License for the specific  language  governing  rights  and  limitations
carlos@0
    40
* under the License.
carlos@0
    41
* The Original Code is Openbravo ERP.
carlos@0
    42
* The Initial Developer of the Original Code is Openbravo SL
carlos@0
    43
* All portions are Copyright (C) 2001-2006 Openbravo SL
carlos@0
    44
* All Rights Reserved.
carlos@0
    45
* Contributor(s):  ______________________________________.
carlos@0
    46
************************************************************************/
carlos@0
    47
  -- Logistice
carlos@0
    48
  v_ResultStr VARCHAR2(2000):='';
carlos@0
    49
  v_Message VARCHAR2(2000):='';
carlos@0
    50
  v_Result NUMBER:=1; -- 0=failure
carlos@0
    51
carlos@0
    52
  v_Aux_New NUMBER;
carlos@0
    53
  v_planned CHAR(1) := 'N';
carlos@0
    54
antonio@735
    55
  v_Stock NUMBER:=0;
carlos@0
    56
  v_neededQty_New NUMBER;
carlos@0
    57
  v_neededQty_Old NUMBER;
carlos@0
    58
  v_Qty_New NUMBER;
carlos@0
    59
  v_Qty_Old NUMBER;
carlos@0
    60
carlos@0
    61
  v_plannedorderdate_new DATE;
carlos@0
    62
  v_planneddate_new DATE;
carlos@0
    63
  v_planneddate_old DATE;
carlos@0
    64
carlos@0
    65
  FINISH_PROCESS BOOLEAN DEFAULT FALSE;
carlos@0
    66
  --  Parameter
carlos@0
    67
  TYPE RECORD IS REF CURSOR;
carlos@0
    68
  Cur_PlanProduct RECORD;
carlos@0
    69
  Cur_Lines RECORD;
carlos@0
    70
carlos@0
    71
BEGIN
carlos@0
    72
  BEGIN --BODY
carlos@0
    73
    v_ResultStr := 'Purchase mrp';
carlos@0
    74
carlos@0
    75
    FOR Cur_PlanProduct IN (
carlos@0
    76
        SELECT MRP_RUN_PURCHASELINE.M_PRODUCT_ID,
carlos@0
    77
          COALESCE(M_PRODUCT_PO.CAPACITY, M_PRODUCT_ORG.CAPACITY, M_PRODUCT.CAPACITY) AS CAPACITY,
carlos@0
    78
          COALESCE(M_PRODUCT_PO.DELIVERYTIME_PROMISED, M_PRODUCT_ORG.DELAYMIN, M_PRODUCT.DELAYMIN, 0) AS DELAYMIN,
carlos@0
    79
          COALESCE(M_PRODUCT_PO.QTYTYPE, M_PRODUCT_ORG.QTYTYPE, M_PRODUCT_ORG.QTYTYPE, 'E') AS qtytype,
carlos@0
    80
          COALESCE(M_PRODUCT_PO.ORDER_MIN, M_PRODUCT_ORG.QTYMIN, M_PRODUCT_ORG.QTYMIN, 0) AS qtymin,
carlos@0
    81
          COALESCE(M_PRODUCT_PO.QTYSTD, M_PRODUCT_ORG.QTYSTD, M_PRODUCT_ORG.QTYSTD, 1) AS qtystd,
carlos@0
    82
          M_PRODUCT_PO.C_BPARTNER_ID AS vendor_ID
carlos@0
    83
        FROM MRP_RUN_PURCHASELINE, M_PRODUCT_PO,
carlos@0
    84
             M_PRODUCT LEFT JOIN M_PRODUCT_ORG ON M_PRODUCT.M_PRODUCT_ID = M_PRODUCT_ORG.M_PRODUCT_ID,
carlos@0
    85
             (SELECT MAX(C_BPARTNER_ID) AS C_BPARTNER_ID, M_PRODUCT_ID
carlos@0
    86
              FROM M_PRODUCT_PO
carlos@0
    87
              WHERE ISCURRENTVENDOR = 'Y'
carlos@0
    88
                AND (p_Vendor_ID IS NULL OR M_PRODUCT_PO.C_BPARTNER_ID = p_Vendor_ID)
carlos@0
    89
              GROUP BY M_PRODUCT_ID) PRODUCT_PO --CASE WITH MORE THAN ONE DEFAULT VENDOR
carlos@0
    90
        WHERE MRP_RUN_PURCHASE_ID = p_Run_ID
carlos@0
    91
          AND M_PRODUCT.M_PRODUCT_ID = M_PRODUCT_PO.M_PRODUCT_ID
carlos@0
    92
          AND M_PRODUCT.M_PRODUCT_ID = MRP_RUN_PURCHASELINE.M_PRODUCT_ID
carlos@0
    93
          AND MRP_RUN_PURCHASELINE.AD_ORG_ID = M_PRODUCT_ORG.AD_ORG_ID
carlos@0
    94
          AND PRODUCT_PO.C_BPARTNER_ID = M_PRODUCT_PO.C_BPARTNER_ID
carlos@0
    95
          AND PRODUCT_PO.M_PRODUCT_ID = M_PRODUCT_PO.M_PRODUCT_ID
carlos@0
    96
          AND M_PRODUCT.ISPURCHASED = 'Y'
carlos@0
    97
      GROUP BY MRP_RUN_PURCHASELINE.M_PRODUCT_ID, M_PRODUCT_PO.CAPACITY, M_PRODUCT_ORG.CAPACITY, M_PRODUCT.CAPACITY,
carlos@0
    98
        M_PRODUCT_PO.DELIVERYTIME_PROMISED, M_PRODUCT_ORG.DELAYMIN, M_PRODUCT.DELAYMIN,
carlos@0
    99
        M_PRODUCT_PO.QTYTYPE, M_PRODUCT_ORG.QTYTYPE, M_PRODUCT_ORG.QTYTYPE,
carlos@0
   100
        M_PRODUCT_PO.ORDER_MIN, M_PRODUCT_ORG.QTYMIN, M_PRODUCT_ORG.QTYMIN,
carlos@0
   101
        M_PRODUCT_PO.QTYSTD, M_PRODUCT_ORG.QTYSTD, M_PRODUCT_ORG.QTYSTD, M_PRODUCT_PO.C_BPARTNER_ID --CASE WITH MORE THAN ONE DEFAULT VENDOR
carlos@0
   102
      ) LOOP
carlos@0
   103
      v_stock := 0;
carlos@0
   104
      v_neededqty_old := NULL;
carlos@0
   105
      v_planneddate_old := NULL;
carlos@0
   106
      FOR Cur_Lines IN (
carlos@0
   107
        SELECT pl.*,
carlos@0
   108
          (CASE WHEN pl.INOUTTRXTYPE = 'ST' THEN 0
gorkaion@1512
   109
                WHEN pl.INOUTTRXTYPE = 'MS' THEN 2
gorkaion@1512
   110
                WHEN pl.QTY >= 0 THEN 1
carlos@0
   111
                ELSE 3 END) AS PRIORITY
carlos@0
   112
        FROM MRP_RUN_PURCHASELINE pl,
carlos@0
   113
          M_PRODUCT
carlos@0
   114
        WHERE pl.MRP_RUN_PURCHASE_ID = p_Run_ID
carlos@0
   115
          AND M_PRODUCT.M_PRODUCT_ID = pl.M_PRODUCT_ID
carlos@0
   116
          AND pl.M_PRODUCT_ID = Cur_PlanProduct.M_Product_ID
carlos@0
   117
        ORDER BY pl.planneddate, priority
carlos@0
   118
        ) LOOP
carlos@0
   119
carlos@0
   120
        v_neededQty_New :=  - Cur_Lines.qty - v_Stock;
gorkaion@239
   121
        IF (v_neededQty_New > 0) THEN
carlos@0
   122
          v_planneddate_new := TO_DATE(Cur_Lines.planneddate) - p_securitymargin;
carlos@0
   123
gorkaion@239
   124
          IF (v_Planneddate_old IS NULL OR TRUNC(v_Planneddate_old) <> TRUNC(v_Planneddate_new)) THEN
carlos@0
   125
            v_planneddate_old := v_planneddate_new;
carlos@0
   126
            UPDATE MRP_RUN_PURCHASELINE
carlos@0
   127
            SET iscompleted = 'Y',
carlos@0
   128
              neededqty = qty
carlos@0
   129
            WHERE MRP_RUN_PURCHASE_ID = p_Run_ID
gorkaion@239
   130
              AND planneddate <= v_planneddate_new;
carlos@0
   131
carlos@0
   132
            v_Qty_New := GREATEST(v_neededqty_New, Cur_PlanProduct.qtymin);
carlos@0
   133
            IF (Cur_PlanProduct.qtytype = 'M') THEN --Multiple lot qty
carlos@0
   134
              v_Qty_new := CEIL(v_qty_new/Cur_PlanProduct.qtystd)*Cur_PlanProduct.qtystd;
carlos@0
   135
            END IF;
carlos@0
   136
carlos@0
   137
            v_plannedorderdate_new := TRUNC(v_planneddate_new -
carlos@0
   138
                                      GREATEST(Cur_PlanProduct.DELAYMIN, (CASE WHEN Cur_PlanProduct.CAPACITY IS NULL THEN 0
carlos@0
   139
                                                                  ELSE CEIL(v_Qty_new/Cur_PlanProduct.CAPACITY)
carlos@0
   140
                                                                  END)));
carlos@36
   141
            Mrp_Run_Insertlines(p_Client_ID, p_Org_ID, p_User_ID, p_Run_ID, Cur_PlanProduct.M_Product_ID, v_qty_new, v_neededqty_new, NULL, 'PP', 'Y', NULL, NULL, NULL, NULL, NULL, v_Planneddate_new, v_plannedorderdate_new, 'N', 'N', Cur_PlanProduct.Vendor_ID, v_Aux_new);
carlos@0
   142
            v_neededqty_old := v_neededqty_new;
carlos@0
   143
            v_qty_old := v_qty_new;
carlos@0
   144
            v_stock := v_stock + v_qty_new;
carlos@0
   145
          ELSE
carlos@0
   146
            v_neededqty_new := v_neededqty_new + COALESCE(v_neededqty_old,0);
carlos@0
   147
            v_qty_new := GREATEST(v_qty_new, v_neededqty_new);
carlos@0
   148
            IF (Cur_PlanProduct.qtytype = 'M') THEN --Multiple lot qty
carlos@0
   149
              v_Qty_new := CEIL(v_qty_new/Cur_PlanProduct.qtystd)*Cur_PlanProduct.qtystd;
carlos@0
   150
            END IF;
carlos@0
   151
carlos@0
   152
            v_plannedorderdate_new := TRUNC(v_planneddate_old -
carlos@0
   153
                                      GREATEST(Cur_PlanProduct.DELAYMIN, (CASE WHEN Cur_PlanProduct.CAPACITY IS NULL THEN 0
carlos@0
   154
                                                                  ELSE CEIL(v_Qty_new/Cur_PlanProduct.CAPACITY)
carlos@0
   155
                                                                  END)));
carlos@0
   156
            UPDATE MRP_RUN_PURCHASELINE
carlos@0
   157
            SET neededqty = v_neededqty_new,
carlos@0
   158
                qty = v_qty_new,
carlos@0
   159
                plannedorderdate = v_plannedorderdate_new
carlos@0
   160
            WHERE MRP_RUN_PURCHASELINE_ID = v_Aux_new;
carlos@0
   161
            v_stock := v_stock + v_qty_new - v_qty_old;
carlos@0
   162
            v_qty_old := v_qty_new;
carlos@0
   163
          END IF;
carlos@0
   164
        END IF;
carlos@0
   165
carlos@0
   166
        v_stock := v_stock + Cur_Lines.qty;
carlos@0
   167
        UPDATE MRP_RUN_PURCHASELINE
carlos@0
   168
        SET CUMQTY = v_stock
carlos@0
   169
        WHERE MRP_RUN_PURCHASELINE_ID = Cur_Lines.MRP_RUN_PURCHASELINE_ID;
carlos@0
   170
carlos@0
   171
      END LOOP;
carlos@0
   172
    END LOOP;
carlos@0
   173
  END; --BODY
carlos@0
   174
EXCEPTION
carlos@0
   175
WHEN OTHERS THEN
carlos@0
   176
  DBMS_OUTPUT.PUT_LINE('MRP_PURCHASEPLAN exception: ' || v_ResultStr);
carlos@0
   177
  RAISE;
carlos@0
   178
--  RETURN;
antonio@735
   179
END MRP_PURCHASEPLAN
gorkaion@239
   180
]]></body>
adrian@94
   181
    </function>
adrian@94
   182
  </database>