database/model/functions/MA_WORKEFFORT_VALIDATE.xml
author Adrián Romero <adrian.romero@openbravo.com>
Tue, 20 Nov 2007 16:27:14 +0000
changeset 94 4e7ba7b8a4ad
parent 0 0247c26f10c6
child 132 33c5ca45fcff
permissions -rw-r--r--
fix: Changed check constraint names and foreign key names to fit in to
30 characteres.
carlos@0
     1
<?xml version="1.0"?>
adrian@94
     2
  <database name="FUNCTION MA_WORKEFFORT_VALIDATE">
adrian@94
     3
    <function name="MA_WORKEFFORT_VALIDATE" type="NULL">
adrian@94
     4
      <parameter name="p_PInstance_ID" type="NUMERIC" mode="in"/>
adrian@94
     5
      <body>
carlos@0
     6
/*************************************************************************
carlos@0
     7
* The contents of this file are subject to the Openbravo  Public  License
carlos@0
     8
* Version  1.0  (the  "License"),  being   the  Mozilla   Public  License
carlos@0
     9
* Version 1.1  with a permitted attribution clause; you may not  use this
carlos@0
    10
* file except in compliance with the License. You  may  obtain  a copy of
carlos@0
    11
* the License at http://www.openbravo.com/legal/license.html
carlos@0
    12
* Software distributed under the License  is  distributed  on  an "AS IS"
carlos@0
    13
* basis, WITHOUT WARRANTY OF ANY KIND, either express or implied. See the
carlos@0
    14
* License for the specific  language  governing  rights  and  limitations
carlos@0
    15
* under the License.
carlos@0
    16
* The Original Code is Openbravo ERP.
carlos@0
    17
* The Initial Developer of the Original Code is Openbravo SL
carlos@0
    18
* All portions are Copyright (C) 2001-2007 Openbravo SL
carlos@0
    19
* All Rights Reserved.
carlos@0
    20
* Contributor(s):  ______________________________________.
carlos@0
    21
************************************************************************/
carlos@0
    22
  -- Logistice
carlos@0
    23
  v_ResultStr VARCHAR2(2000):='';
carlos@0
    24
  v_Message VARCHAR2(2000):='';
carlos@0
    25
  -- Parameter
carlos@0
    26
  TYPE RECORD IS REF CURSOR;
carlos@0
    27
    Cur_Parameter RECORD;
carlos@0
    28
    Cur_Toolset RECORD;
carlos@0
    29
    --
carlos@0
    30
    v_Record_ID NUMBER:=NULL;
carlos@0
    31
    v_User_ID NUMBER;
carlos@0
    32
    v_Org_ID NUMBER;
carlos@0
    33
    v_Client_ID NUMBER;
carlos@0
    34
    v_count NUMBER;
carlos@0
    35
--    v_count2 NUMBER;
carlos@0
    36
--    v_Production_ID NUMBER;
carlos@0
    37
    v_ProductionDate DATE;
carlos@0
    38
--    v_Name NVARCHAR2(60) ;
carlos@0
    39
    -- p_ppline            NUMBER;
carlos@0
    40
    -- p_plline          NUMBER;
carlos@0
    41
--    v_ProductionPlan_ID NUMBER;
carlos@0
    42
--    v_ProductionLine_ID NUMBER;
carlos@0
    43
--    v_Quantity NUMBER;
carlos@0
    44
--    v_UOM_ID NUMBER;
carlos@0
    45
--    v_PInstance NUMBER;
carlos@0
    46
--    v_doneQty NUMBER;
carlos@0
    47
--    v_needQty NUMBER;
carlos@0
    48
    v_QtyOnHand NUMBER;
carlos@0
    49
    p_Processed CHAR;
carlos@0
    50
    v_ProductQty NUMBER;
carlos@0
    51
    v_NextNo NUMBER;
carlos@0
    52
    Quantity NUMBER:=99999; -- unlimited
carlos@0
    53
    v_Result NUMBER:=1;
carlos@0
    54
carlos@0
    55
    CUR_PL_Post RECORD;
carlos@0
    56
    Cur_ProductionPlan RECORD;
carlos@0
    57
carlos@0
    58
    FINISH_PROCESS BOOLEAN:=FALSE;
carlos@0
    59
  BEGIN
carlos@0
    60
    -- Process Parameters
carlos@0
    61
    IF(p_PInstance_ID IS NOT NULL) THEN
carlos@0
    62
      --  Update AD_PInstance
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
      -- Get Parameters
carlos@0
    67
      v_ResultStr:='ReadingParameters';
carlos@0
    68
      FOR Cur_Parameter IN
carlos@0
    69
        (SELECT i.Record_ID, i.AD_User_ID, i.AD_Org_ID, i.AD_Client_ID, p.ParameterName,
carlos@0
    70
          p.P_String, p.P_Number, p.P_Date
carlos@0
    71
        FROM AD_PINSTANCE i
carlos@0
    72
        LEFT JOIN AD_PINSTANCE_PARA p
carlos@0
    73
          ON i.AD_PInstance_ID=p.AD_PInstance_ID
carlos@0
    74
        WHERE i.AD_PInstance_ID=p_PInstance_ID
carlos@0
    75
        ORDER BY p.SeqNo) LOOP
carlos@0
    76
        v_Record_ID:=Cur_Parameter.Record_ID;
carlos@0
    77
        v_User_ID:=Cur_Parameter.AD_User_ID;
carlos@0
    78
        v_Org_ID:=Cur_Parameter.AD_Org_ID;
carlos@0
    79
        v_Client_ID:=Cur_Parameter.AD_Client_ID;
carlos@0
    80
      END LOOP; -- Get Parameter
carlos@0
    81
    ELSE
adrian@94
    82
      DBMS_OUTPUT.PUT_LINE('--&lt;&lt;MA_WorkEffort_Validate&gt;&gt;') ;
carlos@0
    83
    END IF;
carlos@0
    84
  BEGIN --BODY
carlos@0
    85
    SELECT Processed, MOVEMENTDATE
carlos@0
    86
    INTO p_Processed, v_ProductionDate
carlos@0
    87
    FROM M_PRODUCTION
carlos@0
    88
    WHERE M_Production_ID=v_Record_ID;
carlos@0
    89
    --Check if is has been already processed
carlos@0
    90
    IF(p_Processed='Y') THEN
carlos@0
    91
      v_ResultStr:='Work Effort is already validated';
carlos@0
    92
      v_Message:='@WorkEffortValidated@';
carlos@0
    93
      RAISE_APPLICATION_ERROR(-20000, v_Message);
carlos@0
    94
    END IF;
carlos@0
    95
    IF(NOT FINISH_PROCESS) THEN
carlos@0
    96
      -- Check that there are some parts of the job and that theay are processed
carlos@0
    97
      v_ResultStr:='Checking ProductionRun';
carlos@0
    98
      SELECT COUNT(*)
carlos@0
    99
      INTO v_count
carlos@0
   100
      FROM M_PRODUCTIONPLAN
carlos@0
   101
      WHERE M_Production_ID=v_Record_ID;
carlos@0
   102
      IF(v_count=0) THEN
carlos@0
   103
        v_ResultStr := 'There are not Production Runs to validate';
carlos@0
   104
        v_Message:='@NoProductionRun@';
carlos@0
   105
        RAISE_APPLICATION_ERROR(-20000, v_Message);
carlos@0
   106
      END IF;
carlos@0
   107
    END IF; --FINISH_PROCESS
carlos@0
   108
    IF(NOT FINISH_PROCESS) THEN
carlos@0
   109
      SELECT COUNT(*)
carlos@0
   110
      INTO v_count
carlos@0
   111
      FROM M_PRODUCTIONPLAN pp
carlos@0
   112
      WHERE M_Production_ID=v_Record_ID
carlos@0
   113
        AND PROCESSED='N';
adrian@94
   114
      IF(v_count&lt;&gt;0) THEN
carlos@0
   115
        v_Message:='@ProducionRunNoProcessed@';
carlos@0
   116
        RAISE_APPLICATION_ERROR(-20000, v_Message);
carlos@0
   117
        FINISH_PROCESS:=TRUE;
carlos@0
   118
      END IF;
carlos@0
   119
    END IF; --FINISH_PROCESS
carlos@0
   120
    IF(NOT FINISH_PROCESS) THEN
carlos@0
   121
      --Check if there's any global use production phase.
carlos@0
   122
      SELECT COUNT(*)
carlos@0
   123
      INTO v_count
carlos@0
   124
      FROM M_PRODUCTIONPLAN pp,
carlos@0
   125
        MA_WRPHASE wp
carlos@0
   126
      WHERE pp.MA_WRPHASE_ID=wp.MA_WRPHASE_ID
carlos@0
   127
        AND pp.M_PRODUCTION_ID=v_Record_ID
carlos@0
   128
        AND wp.GROUPUSE='Y';
adrian@94
   129
      IF(v_count&lt;&gt;0) THEN
carlos@0
   130
        v_ResultStr:='Distributing product of global use';
carlos@0
   131
        Ma_Globaluse_Distribute(v_Client_ID, v_Org_ID, v_User_ID, v_Record_ID) ;
carlos@0
   132
      END IF;
carlos@0
   133
    END IF; --FINISH_PROCESS
carlos@0
   134
    IF(NOT FINISH_PROCESS) THEN
carlos@0
   135
      --Check if all the ProductionLine have a warehouse
carlos@0
   136
      v_ResultStr:='Checking Locators';
carlos@0
   137
      SELECT COUNT(*)
carlos@0
   138
      INTO v_count
carlos@0
   139
      FROM M_PRODUCTIONLINE l,
carlos@0
   140
        M_PRODUCTIONPLAN p
carlos@0
   141
      WHERE l.M_ProductionPlan_ID=p.M_ProductionPlan_ID
carlos@0
   142
        AND p.M_Production_ID=v_Record_ID
carlos@0
   143
        AND l.M_Locator_ID IS NULL;
adrian@94
   144
      IF(v_count&lt;&gt;0) THEN
carlos@0
   145
        v_ResultStr := 'There are produts without Locator';
carlos@0
   146
        v_Message:='@NeedLocator@';
carlos@0
   147
        RAISE_APPLICATION_ERROR(-20000, v_Message);
carlos@0
   148
        FINISH_PROCESS:=TRUE;
carlos@0
   149
      END IF;
carlos@0
   150
    END IF; --FINISH_PROCESS
carlos@0
   151
    --Check if exist any product in a productionplan with the same locator and productiontype P+ and P-
carlos@0
   152
    IF(NOT FINISH_PROCESS) THEN
carlos@0
   153
      SELECT COUNT(*)
carlos@0
   154
      INTO v_count
carlos@0
   155
      FROM M_PRODUCTIONLINE pl, M_PRODUCTIONPLAN pp
carlos@0
   156
      WHERE pl.PRODUCTIONTYPE='+'
carlos@0
   157
        AND pl.M_PRODUCTIONPLAN_ID = pp.M_PRODUCTIONPLAN_ID
carlos@0
   158
        AND pp.M_PRODUCTION_ID = v_Record_ID
carlos@0
   159
        AND EXISTS
carlos@0
   160
        (SELECT 1
carlos@0
   161
        FROM M_PRODUCTIONLINE
carlos@0
   162
        WHERE M_PRODUCTIONPLAN_ID=pl.M_PRODUCTIONPLAN_ID
carlos@0
   163
          AND M_PRODUCT_ID=pl.M_PRODUCT_ID
carlos@0
   164
          AND PRODUCTIONTYPE='-'
carlos@0
   165
        )
carlos@0
   166
        ;
adrian@94
   167
      IF(v_count&lt;&gt;0) THEN
carlos@0
   168
        ROLLBACK;
carlos@0
   169
        v_ResultStr := 'Same product in a production plan as P+ and P-';
carlos@0
   170
        v_Message:='@P+AndP-InSamePlan@';
carlos@0
   171
        RAISE_APPLICATION_ERROR(-20000, v_Message);
carlos@0
   172
        FINISH_PROCESS:=TRUE;
carlos@0
   173
      END IF;
carlos@0
   174
    END IF; --FINISH_PROCESS
carlos@0
   175
    IF (NOT FINISH_PROCESS) THEN
carlos@0
   176
      SELECT COUNT(*)
carlos@0
   177
      INTO v_Count
carlos@0
   178
      FROM M_PRODUCTIONPLAN PP, M_PRODUCTIONLINE PL, M_PRODUCT P
carlos@0
   179
      WHERE PL.M_PRODUCT_ID=P.M_PRODUCT_ID
carlos@0
   180
        AND P.M_ATTRIBUTESET_ID IS NOT NULL
carlos@0
   181
        AND PL.M_ATTRIBUTESETINSTANCE_ID IS NULL
carlos@0
   182
        AND PL.M_ProductionPlan_ID=pp.M_ProductionPlan_ID
carlos@0
   183
        AND pp.M_Production_ID=v_Record_ID;
adrian@94
   184
      IF v_Count&lt;&gt;0 THEN
carlos@0
   185
        v_Message:='@LinesWithoutAttributeSet@';
carlos@0
   186
        RAISE_APPLICATION_ERROR(-20000, v_Message);
carlos@0
   187
        FINISH_PROCESS:=TRUE;
carlos@0
   188
      END IF;
carlos@0
   189
    END IF;
carlos@0
   190
    -- All Production Lines
carlos@0
   191
    IF(NOT FINISH_PROCESS) THEN
carlos@0
   192
      FOR CUR_PL_Post IN
carlos@0
   193
        (SELECT pl.M_ProductionLine_ID, pl.AD_Client_ID, pl.AD_Org_ID, p.MovementDate,
carlos@0
   194
          pl.M_Product_ID, pl.M_AttributeSetInstance_ID, pl.MovementQty, pl.M_Locator_ID,
carlos@0
   195
          pl.M_Product_UOM_ID, pl.QuantityOrder, pl.C_UOM_ID, pl.LINE, pl.PRODUCTIONTYPE,
carlos@0
   196
          pr.ISSTOCKED, pr.PRODUCTTYPE
carlos@0
   197
        FROM M_PRODUCTION p, M_PRODUCTIONLINE pl, M_PRODUCTIONPLAN pp, M_PRODUCT pr
carlos@0
   198
        WHERE p.M_Production_ID=pp.M_Production_ID
carlos@0
   199
          AND pp.M_ProductionPlan_ID=pl.M_ProductionPlan_ID
carlos@0
   200
          AND pp.M_Production_ID=v_Record_ID
carlos@0
   201
          AND pl.M_PRODUCT_ID=pr.M_PRODUCT_ID
carlos@0
   202
        ORDER BY pp.Line, pl.Line)
carlos@0
   203
      LOOP
carlos@0
   204
        -- M_ProductionLine_ID, AD_Client_ID, AD_Org_ID, MovementDate, M_Product_ID, MovementQty, M_Locator_ID
carlos@0
   205
        -- DBMS_OUTPUT.PUT_LINE('ProductionLine=' || CUR_PL_Post.M_ProductionLine_ID);
carlos@0
   206
        -- DBMS_OUTPUT.PUT_LINE('  Qty=' || CUR_PL_Post.MovementQty || ', OnHand=' || BOM_Qty_OnHand(CUR_PL_Post.M_Product_ID, NULL, CUR_PL_Post.M_Locator_ID));
carlos@0
   207
        -- Check Stock levels for reductions
carlos@0
   208
        -- Check, if product exists and if it is stocked
carlos@0
   209
        -- Unlimited capacity if no item
adrian@94
   210
        IF(CUR_PL_Post.ProductType&lt;&gt;'I' OR CUR_PL_Post.IsStocked='N') THEN
carlos@0
   211
          v_QtyOnHand:=Quantity;
carlos@0
   212
          -- Stocked item
carlos@0
   213
        ELSIF(CUR_PL_Post.IsStocked='Y') THEN
carlos@0
   214
          -- Get ProductQty
carlos@0
   215
          SELECT COALESCE(SUM(QtyOnHand), 0)
carlos@0
   216
          INTO v_ProductQty
carlos@0
   217
          FROM M_STORAGE_DETAIL s
carlos@0
   218
          WHERE M_Product_ID=CUR_PL_Post.M_Product_ID
carlos@0
   219
            AND EXISTS
carlos@0
   220
            (SELECT * FROM M_LOCATOR l WHERE s.M_Locator_ID=l.M_Locator_ID)
carlos@0
   221
            ;
carlos@0
   222
          --DBMS_OUTPUT.PUT_LINE('Qty=' || ProductQty);
carlos@0
   223
          v_QtyOnHand:=v_ProductQty;
carlos@0
   224
        END IF;
adrian@94
   225
        IF(CUR_PL_Post.PRODUCTIONTYPE='-' AND CUR_PL_Post.IsStocked&lt;&gt;'N' AND v_QtyOnHand-CUR_PL_Post.MovementQty&lt;0) THEN
carlos@0
   226
          SELECT '@NotEnoughStocked@: ' || NAME
carlos@0
   227
          INTO v_Message
carlos@0
   228
          FROM M_PRODUCT
carlos@0
   229
          WHERE M_Product_ID=CUR_PL_Post.M_Product_ID;
carlos@0
   230
          RAISE_APPLICATION_ERROR(-20000, v_Message);
carlos@0
   231
          FINISH_PROCESS:=TRUE;
carlos@0
   232
        END IF;
carlos@0
   233
        -- Create Transaction Entry
carlos@0
   234
        v_ResultStr:='CreateTransaction';
carlos@0
   235
        Ad_Sequence_Next('M_Transaction', v_Org_ID, v_NextNo) ;
carlos@0
   236
        INSERT
carlos@0
   237
        INTO M_TRANSACTION
carlos@0
   238
          (
carlos@0
   239
            M_Transaction_ID, M_ProductionLine_ID, AD_Client_ID, AD_Org_ID,
carlos@0
   240
            IsActive, Created, CreatedBy, Updated,
carlos@0
   241
            UpdatedBy, MovementType, M_Locator_ID, M_Product_ID,
carlos@0
   242
            M_AttributeSetInstance_ID, MovementDate, MovementQty, M_Product_UOM_ID,
carlos@0
   243
            QuantityOrder, C_UOM_ID
carlos@0
   244
          )
carlos@0
   245
          VALUES
carlos@0
   246
          (
carlos@0
   247
            v_NextNo, CUR_PL_Post.M_ProductionLine_ID, CUR_PL_Post.AD_Client_ID, CUR_PL_Post.AD_Org_ID,
carlos@0
   248
             'Y', Now(), v_User_ID, Now(),
carlos@0
   249
            v_User_ID, 'P+', CUR_PL_Post.M_Locator_ID, CUR_PL_Post.M_Product_ID,
carlos@0
   250
            COALESCE(CUR_PL_Post.M_AttributeSetInstance_ID, 0), -- not distinguishing between assemby/disassembly
carlos@0
   251
            CUR_PL_Post.MovementDate,(CASE CUR_PL_Post.PRODUCTIONTYPE WHEN '+' THEN CUR_PL_Post.MovementQty ELSE -CUR_PL_Post.MOVEMENTQTY END), CUR_PL_Post.M_Product_UOM_ID,(CASE CUR_PL_Post.PRODUCTIONTYPE WHEN '+' THEN CUR_PL_Post.QUANTITYORDER ELSE -CUR_PL_Post.QuantityOrder END), CUR_PL_Post.C_UOM_ID
carlos@0
   252
          )
carlos@0
   253
          ;
adrian@94
   254
        IF(CUR_PL_Post.IsStocked&lt;&gt;'N') THEN
carlos@0
   255
          M_Check_Stock(CUR_PL_Post.M_Product_ID, v_Client_ID, v_Org_ID, v_Result, v_Message) ;
carlos@0
   256
        END IF;
carlos@0
   257
        IF (v_Result=0) THEN
carlos@0
   258
          v_Message:=v_Message || ' @Inline@ ' || CUR_PL_Post.line;
carlos@0
   259
          RAISE_APPLICATION_ERROR(-20000, v_Message);
carlos@0
   260
          FINISH_PROCESS:=TRUE;
carlos@0
   261
        END IF;
carlos@0
   262
      END LOOP;
carlos@0
   263
    END IF; --FINISH_PROCESS
carlos@0
   264
    IF(NOT FINISH_PROCESS) THEN
carlos@0
   265
        --Calculate Production Cost
carlos@0
   266
        Ma_Production_Cost(v_Record_ID, v_User_ID, v_Message);
carlos@0
   267
    END IF; --FINISH_PROCESS
carlos@0
   268
    IF(NOT FINISH_PROCESS) THEN
carlos@0
   269
      -- Update donequantity on workrequirements
carlos@0
   270
      v_ResultStr:='Updating workrequirement';
carlos@0
   271
      FOR Cur_ProductionPlan IN
carlos@0
   272
        (SELECT *  FROM M_PRODUCTIONPLAN pp  WHERE pp.M_PRODUCTION_ID=v_Record_ID)
carlos@0
   273
      LOOP
carlos@0
   274
        UPDATE MA_WRPHASE
carlos@0
   275
          SET DONEQUANTITY=DONEQUANTITY + Cur_ProductionPlan.PRODUCTIONQTY
carlos@0
   276
        WHERE MA_WRPhase_ID=Cur_ProductionPlan.MA_WRPHASE_ID;
carlos@0
   277
      END LOOP;
carlos@0
   278
      -- Indicate that we are done
carlos@0
   279
      UPDATE M_PRODUCTION
carlos@0
   280
        SET Processed='Y',
carlos@0
   281
        updated=Now(),
carlos@0
   282
        updatedby=v_User_ID
carlos@0
   283
      WHERE M_Production_ID=v_Record_ID;
carlos@0
   284
    END IF; --FINISH_PROCESS
carlos@0
   285
    IF(NOT FINISH_PROCESS) THEN
carlos@0
   286
      v_ResultStr:='Updating used toolsets';
carlos@0
   287
      FOR Cur_Toolset IN
carlos@0
   288
        (SELECT MA_TOOLSETUSED.*
carlos@0
   289
         FROM MA_TOOLSETUSED, M_PRODUCTIONPLAN 
carlos@0
   290
         WHERE MA_TOOLSETUSED.M_PRODUCTIONPLAN_ID = M_PRODUCTIONPLAN.M_PRODUCTIONPLAN_ID
carlos@0
   291
           AND M_PRODUCTIONPLAN.M_PRODUCTION_ID = v_Record_ID) LOOP
carlos@0
   292
        UPDATE MA_TOOLSET
carlos@0
   293
        SET NUMBERUSES = NUMBERUSES + Cur_Toolset.USED
carlos@0
   294
        WHERE MA_TOOLSET_ID = Cur_Toolset.MA_TOOLSET_ID;
carlos@0
   295
      END LOOP;
carlos@0
   296
    END IF;
adrian@94
   297
    --&lt;&lt;FINISH_PROCESS&gt;&gt;
carlos@0
   298
    --v_Message := v_Message || '@Created@: ' || v_NoRecords;
carlos@0
   299
      --  Update AD_PInstance
carlos@0
   300
      DBMS_OUTPUT.PUT_LINE('Updating PInstance - Finished ' || v_Message) ;
carlos@0
   301
      Ad_Update_Pinstance(p_PInstance_ID, NULL, 'N', v_Result, v_Message) ;
carlos@0
   302
    RETURN;
carlos@0
   303
  END; --BODY
carlos@0
   304
EXCEPTION
carlos@0
   305
WHEN OTHERS THEN
carlos@0
   306
  DBMS_OUTPUT.PUT_LINE(v_ResultStr) ;
carlos@0
   307
  v_ResultStr:= '@ERROR=' || SQLERRM;
carlos@0
   308
  DBMS_OUTPUT.PUT_LINE(v_ResultStr) ;
carlos@0
   309
  ROLLBACK;
carlos@0
   310
  Ad_Update_Pinstance(p_PInstance_ID, NULL, 'N', 0, v_ResultStr) ;
carlos@0
   311
  RETURN;
adrian@94
   312
END Ma_Workeffort_Validate
carlos@0
   313
</body>
adrian@94
   314
    </function>
adrian@94
   315
  </database>