src-db/database/model/functions/MA_WORKEFFORT_VALIDATE.xml
author Juan Pablo Aroztegi <juanpablo.aroztegi@openbravo.com>
Wed, 03 Sep 2008 17:55:37 +0000
changeset 1605 8a0fe0193bef
parent 1261 0e35cc0084db
child 1787 84217f37d788
permissions -rw-r--r--
Merge r2.5x intro trunk
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">
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):='';
carlos@0
    26
  -- Parameter
carlos@0
    27
  TYPE RECORD IS REF CURSOR;
carlos@0
    28
    Cur_Parameter RECORD;
carlos@0
    29
    Cur_Toolset RECORD;
carlos@0
    30
    --
juanpablo@1605
    31
    v_Record_ID VARCHAR2(32):=NULL;
juanpablo@1605
    32
    v_User_ID VARCHAR2(32);
juanpablo@1605
    33
    v_Org_ID VARCHAR2(32);
juanpablo@1605
    34
    v_Client_ID VARCHAR2(32);
carlos@0
    35
    v_count NUMBER;
carlos@0
    36
--    v_count2 NUMBER;
juanpablo@1605
    37
--    v_Production_ID VARCHAR2(32);
carlos@0
    38
    v_ProductionDate DATE;
carlos@0
    39
--    v_Name NVARCHAR2(60) ;
carlos@0
    40
    -- p_ppline            NUMBER;
carlos@0
    41
    -- p_plline          NUMBER;
juanpablo@1605
    42
--    v_ProductionPlan_ID VARCHAR2(32);
juanpablo@1605
    43
--    v_ProductionLine_ID VARCHAR2(32);
carlos@0
    44
--    v_Quantity NUMBER;
juanpablo@1605
    45
--    v_UOM_ID VARCHAR2(32);
carlos@0
    46
--    v_PInstance NUMBER;
carlos@0
    47
--    v_doneQty NUMBER;
carlos@0
    48
--    v_needQty NUMBER;
carlos@0
    49
    v_QtyOnHand NUMBER;
carlos@0
    50
    p_Processed CHAR;
carlos@0
    51
    v_ProductQty NUMBER;
juanpablo@1605
    52
    v_NextNo VARCHAR2(32);
carlos@0
    53
    Quantity NUMBER:=99999; -- unlimited
carlos@0
    54
    v_Result NUMBER:=1;
carlos@0
    55
carlos@0
    56
    CUR_PL_Post RECORD;
carlos@0
    57
    Cur_ProductionPlan RECORD;
carlos@0
    58
carlos@0
    59
    FINISH_PROCESS BOOLEAN:=FALSE;
carlos@0
    60
  BEGIN
carlos@0
    61
    -- Process Parameters
carlos@0
    62
    IF(p_PInstance_ID IS NOT NULL) THEN
carlos@0
    63
      --  Update AD_PInstance
carlos@0
    64
      DBMS_OUTPUT.PUT_LINE('Updating PInstance - Processing ' || p_PInstance_ID) ;
carlos@0
    65
      v_ResultStr:='PInstanceNotFound';
antonio@735
    66
      AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'Y', NULL, NULL) ;
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_Org_ID, i.AD_Client_ID, p.ParameterName,
carlos@0
    71
          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) LOOP
carlos@0
    77
        v_Record_ID:=Cur_Parameter.Record_ID;
carlos@0
    78
        v_User_ID:=Cur_Parameter.AD_User_ID;
carlos@0
    79
        v_Org_ID:=Cur_Parameter.AD_Org_ID;
carlos@0
    80
        v_Client_ID:=Cur_Parameter.AD_Client_ID;
carlos@0
    81
      END LOOP; -- Get Parameter
carlos@0
    82
    ELSE
gorkaion@239
    83
      DBMS_OUTPUT.PUT_LINE('--<<MA_WorkEffort_Validate>>') ;
carlos@0
    84
    END IF;
carlos@0
    85
  BEGIN --BODY
carlos@0
    86
    SELECT Processed, MOVEMENTDATE
carlos@0
    87
    INTO p_Processed, v_ProductionDate
carlos@0
    88
    FROM M_PRODUCTION
carlos@0
    89
    WHERE M_Production_ID=v_Record_ID;
carlos@0
    90
    --Check if is has been already processed
carlos@0
    91
    IF(p_Processed='Y') THEN
carlos@0
    92
      v_ResultStr:='Work Effort is already validated';
carlos@0
    93
      v_Message:='@WorkEffortValidated@';
carlos@0
    94
      RAISE_APPLICATION_ERROR(-20000, v_Message);
carlos@0
    95
    END IF;
carlos@0
    96
    IF(NOT FINISH_PROCESS) THEN
carlos@0
    97
      -- Check that there are some parts of the job and that theay are processed
carlos@0
    98
      v_ResultStr:='Checking ProductionRun';
carlos@0
    99
      SELECT COUNT(*)
carlos@0
   100
      INTO v_count
carlos@0
   101
      FROM M_PRODUCTIONPLAN
carlos@0
   102
      WHERE M_Production_ID=v_Record_ID;
carlos@0
   103
      IF(v_count=0) THEN
carlos@0
   104
        v_ResultStr := 'There are not Production Runs to validate';
carlos@0
   105
        v_Message:='@NoProductionRun@';
carlos@0
   106
        RAISE_APPLICATION_ERROR(-20000, v_Message);
carlos@0
   107
      END IF;
carlos@0
   108
    END IF; --FINISH_PROCESS
carlos@0
   109
    IF(NOT FINISH_PROCESS) THEN
carlos@0
   110
      SELECT COUNT(*)
carlos@0
   111
      INTO v_count
carlos@0
   112
      FROM M_PRODUCTIONPLAN pp
carlos@0
   113
      WHERE M_Production_ID=v_Record_ID
carlos@0
   114
        AND PROCESSED='N';
gorkaion@239
   115
      IF(v_count<>0) THEN
carlos@0
   116
        v_Message:='@ProducionRunNoProcessed@';
carlos@0
   117
        RAISE_APPLICATION_ERROR(-20000, v_Message);
carlos@0
   118
        FINISH_PROCESS:=TRUE;
carlos@0
   119
      END IF;
carlos@0
   120
    END IF; --FINISH_PROCESS
carlos@0
   121
    IF(NOT FINISH_PROCESS) THEN
carlos@0
   122
      --Check if there's any global use production phase.
carlos@0
   123
      SELECT COUNT(*)
carlos@0
   124
      INTO v_count
carlos@0
   125
      FROM M_PRODUCTIONPLAN pp,
carlos@0
   126
        MA_WRPHASE wp
carlos@0
   127
      WHERE pp.MA_WRPHASE_ID=wp.MA_WRPHASE_ID
carlos@0
   128
        AND pp.M_PRODUCTION_ID=v_Record_ID
carlos@0
   129
        AND wp.GROUPUSE='Y';
gorkaion@239
   130
      IF(v_count<>0) THEN
carlos@0
   131
        v_ResultStr:='Distributing product of global use';
antonio@735
   132
        MA_GLOBALUSE_DISTRIBUTE(v_Client_ID, v_Org_ID, v_User_ID, v_Record_ID) ;
carlos@0
   133
      END IF;
carlos@0
   134
    END IF; --FINISH_PROCESS
carlos@0
   135
    IF(NOT FINISH_PROCESS) THEN
carlos@0
   136
      --Check if all the ProductionLine have a warehouse
carlos@0
   137
      v_ResultStr:='Checking Locators';
carlos@0
   138
      SELECT COUNT(*)
carlos@0
   139
      INTO v_count
carlos@0
   140
      FROM M_PRODUCTIONLINE l,
carlos@0
   141
        M_PRODUCTIONPLAN p
carlos@0
   142
      WHERE l.M_ProductionPlan_ID=p.M_ProductionPlan_ID
carlos@0
   143
        AND p.M_Production_ID=v_Record_ID
carlos@0
   144
        AND l.M_Locator_ID IS NULL;
gorkaion@239
   145
      IF(v_count<>0) THEN
carlos@0
   146
        v_ResultStr := 'There are produts without Locator';
carlos@0
   147
        v_Message:='@NeedLocator@';
carlos@0
   148
        RAISE_APPLICATION_ERROR(-20000, v_Message);
carlos@0
   149
        FINISH_PROCESS:=TRUE;
carlos@0
   150
      END IF;
carlos@0
   151
    END IF; --FINISH_PROCESS
carlos@0
   152
    --Check if exist any product in a productionplan with the same locator and productiontype P+ and P-
carlos@0
   153
    IF(NOT FINISH_PROCESS) THEN
carlos@0
   154
      SELECT COUNT(*)
carlos@0
   155
      INTO v_count
carlos@0
   156
      FROM M_PRODUCTIONLINE pl, M_PRODUCTIONPLAN pp
carlos@0
   157
      WHERE pl.PRODUCTIONTYPE='+'
carlos@0
   158
        AND pl.M_PRODUCTIONPLAN_ID = pp.M_PRODUCTIONPLAN_ID
carlos@0
   159
        AND pp.M_PRODUCTION_ID = v_Record_ID
carlos@0
   160
        AND EXISTS
carlos@0
   161
        (SELECT 1
carlos@0
   162
        FROM M_PRODUCTIONLINE
carlos@0
   163
        WHERE M_PRODUCTIONPLAN_ID=pl.M_PRODUCTIONPLAN_ID
carlos@0
   164
          AND M_PRODUCT_ID=pl.M_PRODUCT_ID
carlos@0
   165
          AND PRODUCTIONTYPE='-'
carlos@0
   166
        )
carlos@0
   167
        ;
gorkaion@239
   168
      IF(v_count<>0) THEN
carlos@0
   169
        ROLLBACK;
carlos@0
   170
        v_ResultStr := 'Same product in a production plan as P+ and P-';
carlos@0
   171
        v_Message:='@P+AndP-InSamePlan@';
carlos@0
   172
        RAISE_APPLICATION_ERROR(-20000, v_Message);
carlos@0
   173
        FINISH_PROCESS:=TRUE;
carlos@0
   174
      END IF;
carlos@0
   175
    END IF; --FINISH_PROCESS
carlos@0
   176
    IF (NOT FINISH_PROCESS) THEN
carlos@0
   177
      SELECT COUNT(*)
carlos@0
   178
      INTO v_Count
carlos@0
   179
      FROM M_PRODUCTIONPLAN PP, M_PRODUCTIONLINE PL, M_PRODUCT P
carlos@0
   180
      WHERE PL.M_PRODUCT_ID=P.M_PRODUCT_ID
carlos@0
   181
        AND P.M_ATTRIBUTESET_ID IS NOT NULL
juanpablo@1605
   182
        AND COALESCE(PL.M_ATTRIBUTESETINSTANCE_ID, '0') = '0'
carlos@0
   183
        AND PL.M_ProductionPlan_ID=pp.M_ProductionPlan_ID
carlos@0
   184
        AND pp.M_Production_ID=v_Record_ID;
gorkaion@239
   185
      IF v_Count<>0 THEN
carlos@0
   186
        v_Message:='@LinesWithoutAttributeSet@';
carlos@0
   187
        RAISE_APPLICATION_ERROR(-20000, v_Message);
carlos@0
   188
        FINISH_PROCESS:=TRUE;
carlos@0
   189
      END IF;
carlos@0
   190
    END IF;
carlos@0
   191
    -- All Production Lines
carlos@0
   192
    IF(NOT FINISH_PROCESS) THEN
carlos@0
   193
      FOR CUR_PL_Post IN
carlos@0
   194
        (SELECT pl.M_ProductionLine_ID, pl.AD_Client_ID, pl.AD_Org_ID, p.MovementDate,
carlos@0
   195
          pl.M_Product_ID, pl.M_AttributeSetInstance_ID, pl.MovementQty, pl.M_Locator_ID,
carlos@0
   196
          pl.M_Product_UOM_ID, pl.QuantityOrder, pl.C_UOM_ID, pl.LINE, pl.PRODUCTIONTYPE,
carlos@0
   197
          pr.ISSTOCKED, pr.PRODUCTTYPE
carlos@0
   198
        FROM M_PRODUCTION p, M_PRODUCTIONLINE pl, M_PRODUCTIONPLAN pp, M_PRODUCT pr
carlos@0
   199
        WHERE p.M_Production_ID=pp.M_Production_ID
carlos@0
   200
          AND pp.M_ProductionPlan_ID=pl.M_ProductionPlan_ID
carlos@0
   201
          AND pp.M_Production_ID=v_Record_ID
carlos@0
   202
          AND pl.M_PRODUCT_ID=pr.M_PRODUCT_ID
carlos@0
   203
        ORDER BY pp.Line, pl.Line)
carlos@0
   204
      LOOP
carlos@0
   205
        -- M_ProductionLine_ID, AD_Client_ID, AD_Org_ID, MovementDate, M_Product_ID, MovementQty, M_Locator_ID
carlos@0
   206
        -- DBMS_OUTPUT.PUT_LINE('ProductionLine=' || CUR_PL_Post.M_ProductionLine_ID);
carlos@0
   207
        -- 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
   208
        -- Check Stock levels for reductions
carlos@0
   209
        -- Check, if product exists and if it is stocked
carlos@0
   210
        -- Unlimited capacity if no item
gorkaion@239
   211
        IF(CUR_PL_Post.ProductType<>'I' OR CUR_PL_Post.IsStocked='N') THEN
carlos@0
   212
          v_QtyOnHand:=Quantity;
carlos@0
   213
          -- Stocked item
carlos@0
   214
        ELSIF(CUR_PL_Post.IsStocked='Y') THEN
carlos@0
   215
          -- Get ProductQty
carlos@0
   216
          SELECT COALESCE(SUM(QtyOnHand), 0)
carlos@0
   217
          INTO v_ProductQty
carlos@0
   218
          FROM M_STORAGE_DETAIL s
carlos@0
   219
          WHERE M_Product_ID=CUR_PL_Post.M_Product_ID
carlos@0
   220
            AND EXISTS
carlos@0
   221
            (SELECT * FROM M_LOCATOR l WHERE s.M_Locator_ID=l.M_Locator_ID)
carlos@0
   222
            ;
carlos@0
   223
          --DBMS_OUTPUT.PUT_LINE('Qty=' || ProductQty);
carlos@0
   224
          v_QtyOnHand:=v_ProductQty;
carlos@0
   225
        END IF;
gorkaion@239
   226
        IF(CUR_PL_Post.PRODUCTIONTYPE='-' AND CUR_PL_Post.IsStocked<>'N' AND v_QtyOnHand-CUR_PL_Post.MovementQty<0) THEN
carlos@0
   227
          SELECT '@NotEnoughStocked@: ' || NAME
carlos@0
   228
          INTO v_Message
carlos@0
   229
          FROM M_PRODUCT
carlos@0
   230
          WHERE M_Product_ID=CUR_PL_Post.M_Product_ID;
carlos@0
   231
          RAISE_APPLICATION_ERROR(-20000, v_Message);
carlos@0
   232
          FINISH_PROCESS:=TRUE;
carlos@0
   233
        END IF;
carlos@0
   234
        -- Create Transaction Entry
carlos@0
   235
        v_ResultStr:='CreateTransaction';
carlos@0
   236
        Ad_Sequence_Next('M_Transaction', v_Org_ID, v_NextNo) ;
carlos@0
   237
        INSERT
carlos@0
   238
        INTO M_TRANSACTION
carlos@0
   239
          (
carlos@0
   240
            M_Transaction_ID, M_ProductionLine_ID, AD_Client_ID, AD_Org_ID,
carlos@0
   241
            IsActive, Created, CreatedBy, Updated,
carlos@0
   242
            UpdatedBy, MovementType, M_Locator_ID, M_Product_ID,
carlos@0
   243
            M_AttributeSetInstance_ID, MovementDate, MovementQty, M_Product_UOM_ID,
carlos@0
   244
            QuantityOrder, C_UOM_ID
carlos@0
   245
          )
carlos@0
   246
          VALUES
carlos@0
   247
          (
carlos@0
   248
            v_NextNo, CUR_PL_Post.M_ProductionLine_ID, CUR_PL_Post.AD_Client_ID, CUR_PL_Post.AD_Org_ID,
antonio@735
   249
             'Y', now(), v_User_ID, now(),
carlos@0
   250
            v_User_ID, 'P+', CUR_PL_Post.M_Locator_ID, CUR_PL_Post.M_Product_ID,
juanpablo@1605
   251
            COALESCE(CUR_PL_Post.M_AttributeSetInstance_ID, '0'), -- not distinguishing between assemby/disassembly
carlos@0
   252
            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
   253
          )
carlos@0
   254
          ;
gorkaion@239
   255
        IF(CUR_PL_Post.IsStocked<>'N') THEN
carlos@0
   256
          M_Check_Stock(CUR_PL_Post.M_Product_ID, v_Client_ID, v_Org_ID, v_Result, v_Message) ;
carlos@0
   257
        END IF;
carlos@0
   258
        IF (v_Result=0) THEN
carlos@0
   259
          v_Message:=v_Message || ' @Inline@ ' || CUR_PL_Post.line;
carlos@0
   260
          RAISE_APPLICATION_ERROR(-20000, v_Message);
carlos@0
   261
          FINISH_PROCESS:=TRUE;
carlos@0
   262
        END IF;
carlos@0
   263
      END LOOP;
carlos@0
   264
    END IF; --FINISH_PROCESS
carlos@0
   265
    IF(NOT FINISH_PROCESS) THEN
carlos@0
   266
        --Calculate Production Cost
carlos@0
   267
        Ma_Production_Cost(v_Record_ID, v_User_ID, v_Message);
carlos@0
   268
    END IF; --FINISH_PROCESS
carlos@0
   269
    IF(NOT FINISH_PROCESS) THEN
carlos@0
   270
      -- Update donequantity on workrequirements
carlos@0
   271
      v_ResultStr:='Updating workrequirement';
carlos@0
   272
      FOR Cur_ProductionPlan IN
carlos@0
   273
        (SELECT *  FROM M_PRODUCTIONPLAN pp  WHERE pp.M_PRODUCTION_ID=v_Record_ID)
carlos@0
   274
      LOOP
carlos@0
   275
        UPDATE MA_WRPHASE
carlos@0
   276
          SET DONEQUANTITY=DONEQUANTITY + Cur_ProductionPlan.PRODUCTIONQTY
carlos@0
   277
        WHERE MA_WRPhase_ID=Cur_ProductionPlan.MA_WRPHASE_ID;
carlos@0
   278
      END LOOP;
carlos@0
   279
      -- Indicate that we are done
carlos@0
   280
      UPDATE M_PRODUCTION
carlos@0
   281
        SET Processed='Y',
antonio@735
   282
        updated=now(),
carlos@0
   283
        updatedby=v_User_ID
carlos@0
   284
      WHERE M_Production_ID=v_Record_ID;
carlos@0
   285
    END IF; --FINISH_PROCESS
carlos@0
   286
    IF(NOT FINISH_PROCESS) THEN
carlos@0
   287
      v_ResultStr:='Updating used toolsets';
carlos@0
   288
      FOR Cur_Toolset IN
carlos@0
   289
        (SELECT MA_TOOLSETUSED.*
antonio@737
   290
         FROM MA_TOOLSETUSED, M_PRODUCTIONPLAN
carlos@0
   291
         WHERE MA_TOOLSETUSED.M_PRODUCTIONPLAN_ID = M_PRODUCTIONPLAN.M_PRODUCTIONPLAN_ID
carlos@0
   292
           AND M_PRODUCTIONPLAN.M_PRODUCTION_ID = v_Record_ID) LOOP
carlos@0
   293
        UPDATE MA_TOOLSET
carlos@0
   294
        SET NUMBERUSES = NUMBERUSES + Cur_Toolset.USED
carlos@0
   295
        WHERE MA_TOOLSET_ID = Cur_Toolset.MA_TOOLSET_ID;
carlos@0
   296
      END LOOP;
carlos@0
   297
    END IF;
gorkaion@239
   298
    --<<FINISH_PROCESS>>
carlos@0
   299
    --v_Message := v_Message || '@Created@: ' || v_NoRecords;
carlos@0
   300
      --  Update AD_PInstance
carlos@0
   301
      DBMS_OUTPUT.PUT_LINE('Updating PInstance - Finished ' || v_Message) ;
antonio@735
   302
      AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'N', v_Result, v_Message) ;
carlos@0
   303
    RETURN;
carlos@0
   304
  END; --BODY
carlos@0
   305
EXCEPTION
carlos@0
   306
WHEN OTHERS THEN
carlos@0
   307
  DBMS_OUTPUT.PUT_LINE(v_ResultStr) ;
carlos@0
   308
  v_ResultStr:= '@ERROR=' || SQLERRM;
carlos@0
   309
  DBMS_OUTPUT.PUT_LINE(v_ResultStr) ;
carlos@0
   310
  ROLLBACK;
antonio@735
   311
  AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'N', 0, v_ResultStr) ;
carlos@0
   312
  RETURN;
antonio@735
   313
END MA_WORKEFFORT_VALIDATE
gorkaion@239
   314
]]></body>
adrian@94
   315
    </function>
adrian@94
   316
  </database>