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