src-db/database/model/functions/MA_WORKEFFORT_VALIDATE.xml
author Rafa Roda Palacios <rafa.roda@ubiquads.com>
Wed, 28 May 2014 18:09:28 +0200
changeset 23401 fabc81386bec
parent 20972 3f5e8c7117d6
child 23448 f371e1261fd9
permissions -rw-r--r--
Fixes issue 26514 Validate Work Effort only inserts in M_TRANSACTION table when movement Quantity is <> 0
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
priya@9072
     9
* Version  1.1  (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.
ggi@6701
    18
* The Initial Developer of the Original Code is Openbravo SLU
rafa@23401
    19
* All portions are Copyright (C) 2001-2014 Openbravo SLU
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;
gorkaion@2007
    30
    Cur_PP RECORD;
carlos@0
    31
    --
juanpablo@1605
    32
    v_Record_ID VARCHAR2(32):=NULL;
juanpablo@1605
    33
    v_User_ID VARCHAR2(32);
juanpablo@1605
    34
    v_Org_ID VARCHAR2(32);
juanpablo@1605
    35
    v_Client_ID VARCHAR2(32);
carlos@0
    36
    v_count NUMBER;
carlos@0
    37
--    v_count2 NUMBER;
juanpablo@1605
    38
--    v_Production_ID VARCHAR2(32);
carlos@0
    39
    v_ProductionDate DATE;
carlos@0
    40
--    v_Name NVARCHAR2(60) ;
carlos@0
    41
    -- p_ppline            NUMBER;
carlos@0
    42
    -- p_plline          NUMBER;
juanpablo@1605
    43
--    v_ProductionPlan_ID VARCHAR2(32);
juanpablo@1605
    44
--    v_ProductionLine_ID VARCHAR2(32);
carlos@0
    45
--    v_Quantity NUMBER;
juanpablo@1605
    46
--    v_UOM_ID VARCHAR2(32);
carlos@0
    47
--    v_PInstance NUMBER;
carlos@0
    48
--    v_doneQty NUMBER;
carlos@0
    49
--    v_needQty NUMBER;
carlos@0
    50
    v_QtyOnHand NUMBER;
carlos@0
    51
    p_Processed CHAR;
carlos@0
    52
    v_ProductQty NUMBER;
juanpablo@1605
    53
    v_NextNo VARCHAR2(32);
carlos@0
    54
    Quantity NUMBER:=99999; -- unlimited
carlos@0
    55
    v_Result NUMBER:=1;
carlos@0
    56
carlos@0
    57
    CUR_PL_Post RECORD;
carlos@0
    58
    Cur_ProductionPlan RECORD;
carlos@0
    59
carlos@0
    60
    FINISH_PROCESS BOOLEAN:=FALSE;
asier@1929
    61
    v_is_included NUMBER:=0;
asier@1929
    62
    v_available_period NUMBER:=0;
asier@1929
    63
    v_is_ready AD_Org.IsReady%TYPE;
asier@1929
    64
    v_is_tr_allow AD_OrgType.IsTransactionsAllowed%TYPE;
victor@3065
    65
    v_isacctle AD_OrgType.IsAcctLegalEntity%TYPE;
victor@3065
    66
    v_org_bule_id AD_Org.AD_Org_ID%TYPE;
asier@1929
    67
    v_AD_Org_ID VARCHAR2(32);
rafael@6085
    68
    v_prodline NUMBER;
rafael@6085
    69
    v_line NUMBER;
rdm@14983
    70
    v_AD_Pinstance_ID VARCHAR2(32);
gorkaion@20940
    71
    v_productname m_product.name%TYPE;
carlos@0
    72
  BEGIN
carlos@0
    73
    -- Process Parameters
carlos@0
    74
    IF(p_PInstance_ID IS NOT NULL) THEN
carlos@0
    75
      --  Update AD_PInstance
carlos@0
    76
      DBMS_OUTPUT.PUT_LINE('Updating PInstance - Processing ' || p_PInstance_ID) ;
carlos@0
    77
      v_ResultStr:='PInstanceNotFound';
antonio@735
    78
      AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'Y', NULL, NULL) ;
carlos@0
    79
      -- Get Parameters
carlos@0
    80
      v_ResultStr:='ReadingParameters';
carlos@0
    81
      FOR Cur_Parameter IN
carlos@0
    82
        (SELECT i.Record_ID, i.AD_User_ID, i.AD_Org_ID, i.AD_Client_ID, p.ParameterName,
carlos@0
    83
          p.P_String, p.P_Number, p.P_Date
carlos@0
    84
        FROM AD_PINSTANCE i
carlos@0
    85
        LEFT JOIN AD_PINSTANCE_PARA p
carlos@0
    86
          ON i.AD_PInstance_ID=p.AD_PInstance_ID
carlos@0
    87
        WHERE i.AD_PInstance_ID=p_PInstance_ID
carlos@0
    88
        ORDER BY p.SeqNo) LOOP
carlos@0
    89
        v_Record_ID:=Cur_Parameter.Record_ID;
carlos@0
    90
        v_User_ID:=Cur_Parameter.AD_User_ID;
carlos@0
    91
        v_Org_ID:=Cur_Parameter.AD_Org_ID;
carlos@0
    92
        v_Client_ID:=Cur_Parameter.AD_Client_ID;
carlos@0
    93
      END LOOP; -- Get Parameter
carlos@0
    94
    ELSE
gorkaion@239
    95
      DBMS_OUTPUT.PUT_LINE('--<<MA_WorkEffort_Validate>>') ;
carlos@0
    96
    END IF;
carlos@0
    97
  BEGIN --BODY
asier@1929
    98
    SELECT Processed, MOVEMENTDATE, AD_ORG_ID
asier@1929
    99
    INTO p_Processed, v_ProductionDate, v_AD_Org_ID
carlos@0
   100
    FROM M_PRODUCTION
carlos@0
   101
    WHERE M_Production_ID=v_Record_ID;
carlos@0
   102
    --Check if is has been already processed
carlos@0
   103
    IF(p_Processed='Y') THEN
carlos@0
   104
      v_ResultStr:='Work Effort is already validated';
carlos@0
   105
      v_Message:='@WorkEffortValidated@';
carlos@0
   106
      RAISE_APPLICATION_ERROR(-20000, v_Message);
carlos@0
   107
    END IF;
gorkaion@20972
   108
    SELECT count(*) INTO v_count
gorkaion@20972
   109
    FROM dual
gorkaion@20972
   110
    WHERE EXISTS (
gorkaion@20972
   111
        SELECT 1
gorkaion@20972
   112
        FROM m_productionplan pp
gorkaion@20972
   113
            JOIN m_productionline pl ON pp.m_productionplan_id = pl.m_productionplan_id
gorkaion@20972
   114
            JOIN m_product p ON p.m_product_id = pl.m_product_id
gorkaion@20972
   115
        WHERE pp.m_production_id = v_record_id
gorkaion@20972
   116
          AND p.isgeneric = 'Y');
gorkaion@20940
   117
    IF (v_count > 0) THEN
gorkaion@20972
   118
      SELECT max(p.name) INTO v_productname
gorkaion@20972
   119
      FROM m_productionplan pp
gorkaion@20972
   120
          JOIN m_productionline pl ON pp.m_productionplan_id = pl.m_productionplan_id
gorkaion@20972
   121
          JOIN m_product p ON p.m_product_id = pl.m_product_id
gorkaion@20972
   122
      WHERE pp.m_production_id = v_record_id
gorkaion@20972
   123
        AND p.isgeneric = 'Y';
gorkaion@20940
   124
      RAISE_APPLICATION_ERROR(-20000, '@CannotUseGenericProduct@ ' || v_productName);
gorkaion@20940
   125
    END IF;
gorkaion@20940
   126
    
carlos@0
   127
    IF(NOT FINISH_PROCESS) THEN
carlos@0
   128
      -- Check that there are some parts of the job and that theay are processed
asier@1929
   129
      
asier@1929
   130
      -- Check the header belongs to a organization where transactions are posible and ready to use
asier@1929
   131
      SELECT AD_Org.IsReady, Ad_OrgType.IsTransactionsAllowed
asier@1929
   132
      INTO v_is_ready, v_is_tr_allow
asier@1929
   133
      FROM M_PRODUCTION, AD_Org, AD_OrgType
asier@1929
   134
      WHERE AD_Org.AD_Org_ID=M_PRODUCTION.AD_Org_ID
asier@1929
   135
      AND AD_Org.AD_OrgType_ID=AD_OrgType.AD_OrgType_ID
asier@1929
   136
      AND M_PRODUCTION.M_PRODUCTION_ID=v_Record_ID;
asier@1929
   137
      IF (v_is_ready='N') THEN
asier@1929
   138
        RAISE_APPLICATION_ERROR(-20000, '@OrgHeaderNotReady@');
asier@1929
   139
      END IF;
asier@1929
   140
      IF (v_is_tr_allow='N') THEN
asier@1929
   141
        RAISE_APPLICATION_ERROR(-20000, '@OrgHeaderNotTransAllowed@');
asier@1929
   142
      END IF;
asier@1929
   143
      
gorkaion@2007
   144
      SELECT AD_ORG_CHK_DOCUMENTS('M_PRODUCTION', 'M_PRODUCTIONPLAN', v_Record_ID, 'M_PRODUCTION_ID', 'M_PRODUCTION_ID') INTO v_is_included FROM dual;
asier@1929
   145
      IF (v_is_included=-1) THEN
asier@1929
   146
        RAISE_APPLICATION_ERROR(-20000, '@LinesAndHeaderDifferentLEorBU@');
asier@1929
   147
      END IF;
gorkaion@2007
   148
      FOR CUR_PP IN
gorkaion@2007
   149
        (SELECT M_PRODUCTIONPLAN_ID
gorkaion@2007
   150
         FROM M_PRODUCTIONPLAN
gorkaion@2007
   151
         WHERE M_PRODUCTION_ID = v_Record_ID) LOOP
gorkaion@2007
   152
        SELECT AD_ORG_CHK_DOCUMENTS('M_PRODUCTIONPLAN', 'M_PRODUCTIONLINE', CUR_PP.M_PRODUCTIONPLAN_ID, 'M_PRODUCTIONPLAN_ID', 'M_PRODUCTIONPLAN_ID') INTO v_is_included FROM dual;
gorkaion@2007
   153
        IF (v_is_included=-1) THEN
gorkaion@2007
   154
          RAISE_APPLICATION_ERROR(-20000, '@LinesAndHeaderDifferentLEorBU@');
gorkaion@2007
   155
        END IF;
victor@3065
   156
      END LOOP;      
asier@1929
   157
      
victor@3065
   158
      -- Check the period control is opened (only if it is legal entity with accounting)
victor@3065
   159
      -- Gets the BU or LE of the document
victor@3162
   160
      SELECT AD_GET_DOC_LE_BU('M_PRODUCTION', v_Record_ID, 'M_PRODUCTION_ID', 'LE')
victor@3065
   161
      INTO v_org_bule_id
victor@3065
   162
      FROM DUAL;
asier@1929
   163
      
victor@3065
   164
      SELECT AD_OrgType.IsAcctLegalEntity
victor@3065
   165
      INTO v_isacctle
victor@3065
   166
      FROM AD_OrgType, AD_Org
victor@3065
   167
      WHERE AD_Org.AD_OrgType_ID = AD_OrgType.AD_OrgType_ID
victor@3065
   168
      AND AD_Org.AD_Org_ID=v_org_bule_id;
victor@3065
   169
      
victor@3065
   170
      IF (v_isacctle='Y') THEN
victor@3065
   171
        SELECT C_CHK_OPEN_PERIOD(v_AD_Org_ID, v_ProductionDate, 'MMP', NULL) 
victor@3065
   172
        INTO v_available_period
victor@3065
   173
        FROM DUAL;
victor@3065
   174
        
victor@3065
   175
        IF (v_available_period<>1) THEN
victor@3065
   176
          RAISE_APPLICATION_ERROR(-20000, '@PeriodNotAvailable@');
victor@3065
   177
        END IF;
asier@1929
   178
      END IF;
asier@1929
   179
      
victor@3065
   180
      
carlos@0
   181
      v_ResultStr:='Checking ProductionRun';
carlos@0
   182
      SELECT COUNT(*)
carlos@0
   183
      INTO v_count
carlos@0
   184
      FROM M_PRODUCTIONPLAN
carlos@0
   185
      WHERE M_Production_ID=v_Record_ID;
carlos@0
   186
      IF(v_count=0) THEN
carlos@0
   187
        v_ResultStr := 'There are not Production Runs to validate';
carlos@0
   188
        v_Message:='@NoProductionRun@';
carlos@0
   189
        RAISE_APPLICATION_ERROR(-20000, v_Message);
carlos@0
   190
      END IF;
carlos@0
   191
    END IF; --FINISH_PROCESS
carlos@0
   192
    IF(NOT FINISH_PROCESS) THEN
carlos@0
   193
      SELECT COUNT(*)
carlos@0
   194
      INTO v_count
carlos@0
   195
      FROM M_PRODUCTIONPLAN pp
carlos@0
   196
      WHERE M_Production_ID=v_Record_ID
carlos@0
   197
        AND PROCESSED='N';
gorkaion@239
   198
      IF(v_count<>0) THEN
carlos@0
   199
        v_Message:='@ProducionRunNoProcessed@';
carlos@0
   200
        RAISE_APPLICATION_ERROR(-20000, v_Message);
carlos@0
   201
        FINISH_PROCESS:=TRUE;
carlos@0
   202
      END IF;
carlos@0
   203
    END IF; --FINISH_PROCESS
carlos@0
   204
    IF(NOT FINISH_PROCESS) THEN
carlos@0
   205
      --Check if there's any global use production phase.
carlos@0
   206
      SELECT COUNT(*)
carlos@0
   207
      INTO v_count
carlos@0
   208
      FROM M_PRODUCTIONPLAN pp,
carlos@0
   209
        MA_WRPHASE wp
carlos@0
   210
      WHERE pp.MA_WRPHASE_ID=wp.MA_WRPHASE_ID
carlos@0
   211
        AND pp.M_PRODUCTION_ID=v_Record_ID
carlos@0
   212
        AND wp.GROUPUSE='Y';
gorkaion@239
   213
      IF(v_count<>0) THEN
carlos@0
   214
        v_ResultStr:='Distributing product of global use';
javier@14281
   215
        MA_GLOBALUSE_DISTRIBUTE(v_Client_ID, v_AD_Org_ID, v_User_ID, v_Record_ID) ;
carlos@0
   216
      END IF;
carlos@0
   217
    END IF; --FINISH_PROCESS
carlos@0
   218
    IF(NOT FINISH_PROCESS) THEN
carlos@0
   219
      --Check if all the ProductionLine have a warehouse
carlos@0
   220
      v_ResultStr:='Checking Locators';
carlos@0
   221
      SELECT COUNT(*)
carlos@0
   222
      INTO v_count
carlos@0
   223
      FROM M_PRODUCTIONLINE l,
carlos@0
   224
        M_PRODUCTIONPLAN p
carlos@0
   225
      WHERE l.M_ProductionPlan_ID=p.M_ProductionPlan_ID
carlos@0
   226
        AND p.M_Production_ID=v_Record_ID
carlos@0
   227
        AND l.M_Locator_ID IS NULL;
gorkaion@239
   228
      IF(v_count<>0) THEN
carlos@0
   229
        v_ResultStr := 'There are produts without Locator';
carlos@0
   230
        v_Message:='@NeedLocator@';
carlos@0
   231
        RAISE_APPLICATION_ERROR(-20000, v_Message);
carlos@0
   232
        FINISH_PROCESS:=TRUE;
carlos@0
   233
      END IF;
carlos@0
   234
    END IF; --FINISH_PROCESS
carlos@0
   235
    --Check if exist any product in a productionplan with the same locator and productiontype P+ and P-
carlos@0
   236
    IF(NOT FINISH_PROCESS) THEN
carlos@0
   237
      SELECT COUNT(*)
carlos@0
   238
      INTO v_count
carlos@0
   239
      FROM M_PRODUCTIONLINE pl, M_PRODUCTIONPLAN pp
carlos@0
   240
      WHERE pl.PRODUCTIONTYPE='+'
carlos@0
   241
        AND pl.M_PRODUCTIONPLAN_ID = pp.M_PRODUCTIONPLAN_ID
carlos@0
   242
        AND pp.M_PRODUCTION_ID = v_Record_ID
carlos@0
   243
        AND EXISTS
carlos@0
   244
        (SELECT 1
carlos@0
   245
        FROM M_PRODUCTIONLINE
carlos@0
   246
        WHERE M_PRODUCTIONPLAN_ID=pl.M_PRODUCTIONPLAN_ID
carlos@0
   247
          AND M_PRODUCT_ID=pl.M_PRODUCT_ID
carlos@0
   248
          AND PRODUCTIONTYPE='-'
carlos@0
   249
        )
carlos@0
   250
        ;
gorkaion@239
   251
      IF(v_count<>0) THEN
carlos@0
   252
        ROLLBACK;
carlos@0
   253
        v_ResultStr := 'Same product in a production plan as P+ and P-';
carlos@0
   254
        v_Message:='@P+AndP-InSamePlan@';
carlos@0
   255
        RAISE_APPLICATION_ERROR(-20000, v_Message);
carlos@0
   256
        FINISH_PROCESS:=TRUE;
carlos@0
   257
      END IF;
carlos@0
   258
    END IF; --FINISH_PROCESS
carlos@0
   259
    IF (NOT FINISH_PROCESS) THEN
rafael@6085
   260
      SELECT COUNT(*), MAX(pp.line), MAX(PL.LINE)
rafael@6085
   261
      INTO v_Count, v_prodline, v_line
carlos@0
   262
      FROM M_PRODUCTIONPLAN PP, M_PRODUCTIONLINE PL, M_PRODUCT P
carlos@0
   263
      WHERE PL.M_PRODUCT_ID=P.M_PRODUCT_ID
carlos@0
   264
        AND P.M_ATTRIBUTESET_ID IS NOT NULL
rafael@6085
   265
        AND (P.ATTRSETVALUETYPE IS NULL OR P.ATTRSETVALUETYPE <> 'F')
rafael@6098
   266
        AND (SELECT ISONEATTRSETVALREQUIRED FROM M_ATTRIBUTESET WHERE M_ATTRIBUTESET_ID = P.M_ATTRIBUTESET_ID) = 'Y'
juanpablo@1605
   267
        AND COALESCE(PL.M_ATTRIBUTESETINSTANCE_ID, '0') = '0'
carlos@0
   268
        AND PL.M_ProductionPlan_ID=pp.M_ProductionPlan_ID
carlos@0
   269
        AND pp.M_Production_ID=v_Record_ID;
gorkaion@239
   270
      IF v_Count<>0 THEN
rafael@6085
   271
        RAISE_APPLICATION_ERROR(-20000, '@inProductionPlan@'||' '||'@line@'||' '||v_prodline||', '||'@Inline@'||' '||v_line||' '||'@productWithoutAttributeSet@') ;
carlos@0
   272
        FINISH_PROCESS:=TRUE;
carlos@0
   273
      END IF;
carlos@0
   274
    END IF;
carlos@0
   275
    -- All Production Lines
carlos@0
   276
    IF(NOT FINISH_PROCESS) THEN
carlos@0
   277
      FOR CUR_PL_Post IN
carlos@0
   278
        (SELECT pl.M_ProductionLine_ID, pl.AD_Client_ID, pl.AD_Org_ID, p.MovementDate,
carlos@0
   279
          pl.M_Product_ID, pl.M_AttributeSetInstance_ID, pl.MovementQty, pl.M_Locator_ID,
carlos@0
   280
          pl.M_Product_UOM_ID, pl.QuantityOrder, pl.C_UOM_ID, pl.LINE, pl.PRODUCTIONTYPE,
carlos@0
   281
          pr.ISSTOCKED, pr.PRODUCTTYPE
carlos@0
   282
        FROM M_PRODUCTION p, M_PRODUCTIONLINE pl, M_PRODUCTIONPLAN pp, M_PRODUCT pr
carlos@0
   283
        WHERE p.M_Production_ID=pp.M_Production_ID
carlos@0
   284
          AND pp.M_ProductionPlan_ID=pl.M_ProductionPlan_ID
carlos@0
   285
          AND pp.M_Production_ID=v_Record_ID
carlos@0
   286
          AND pl.M_PRODUCT_ID=pr.M_PRODUCT_ID
sivaraman@7675
   287
          AND pr.ISSTOCKED='Y'
carlos@0
   288
        ORDER BY pp.Line, pl.Line)
carlos@0
   289
      LOOP
carlos@0
   290
        -- M_ProductionLine_ID, AD_Client_ID, AD_Org_ID, MovementDate, M_Product_ID, MovementQty, M_Locator_ID
carlos@0
   291
        -- DBMS_OUTPUT.PUT_LINE('ProductionLine=' || CUR_PL_Post.M_ProductionLine_ID);
gorkaion@1787
   292
        -- DBMS_OUTPUT.PUT_LINE('  Qty=' || CUR_PL_Post.MovementQty || ', OnHand=' || M_BOM_Qty_OnHand(CUR_PL_Post.M_Product_ID, NULL, CUR_PL_Post.M_Locator_ID));
carlos@0
   293
        -- Check Stock levels for reductions
carlos@0
   294
        -- Check, if product exists and if it is stocked
carlos@0
   295
        -- Unlimited capacity if no item
gorkaion@239
   296
        IF(CUR_PL_Post.ProductType<>'I' OR CUR_PL_Post.IsStocked='N') THEN
carlos@0
   297
          v_QtyOnHand:=Quantity;
carlos@0
   298
          -- Stocked item
carlos@0
   299
        ELSIF(CUR_PL_Post.IsStocked='Y') THEN
carlos@0
   300
          -- Get ProductQty
carlos@0
   301
          SELECT COALESCE(SUM(QtyOnHand), 0)
carlos@0
   302
          INTO v_ProductQty
carlos@0
   303
          FROM M_STORAGE_DETAIL s
carlos@0
   304
          WHERE M_Product_ID=CUR_PL_Post.M_Product_ID
carlos@0
   305
            AND EXISTS
carlos@0
   306
            (SELECT * FROM M_LOCATOR l WHERE s.M_Locator_ID=l.M_Locator_ID)
carlos@0
   307
            ;
carlos@0
   308
          --DBMS_OUTPUT.PUT_LINE('Qty=' || ProductQty);
carlos@0
   309
          v_QtyOnHand:=v_ProductQty;
carlos@0
   310
        END IF;
rafa@23401
   311
        -- Only insert in M_TRANSACTION if MovementQty <> 0
rafa@23401
   312
        IF CUR_PL_Post.MovementQty <> 0 THEN
rafa@23401
   313
          -- Create Transaction Entry        
rafa@23401
   314
           v_ResultStr:='CreateTransaction';
rafa@23401
   315
          Ad_Sequence_Next('M_Transaction', v_Org_ID, v_NextNo) ;
rafa@23401
   316
          INSERT
rafa@23401
   317
          INTO M_TRANSACTION
rafa@23401
   318
            (
rafa@23401
   319
              M_Transaction_ID, M_ProductionLine_ID, AD_Client_ID, AD_Org_ID,
rafa@23401
   320
              IsActive, Created, CreatedBy, Updated,
rafa@23401
   321
              UpdatedBy, MovementType, M_Locator_ID, M_Product_ID,
rafa@23401
   322
              M_AttributeSetInstance_ID, MovementDate, MovementQty, M_Product_UOM_ID,
rafa@23401
   323
              QuantityOrder, C_UOM_ID
rafa@23401
   324
            )
rafa@23401
   325
            VALUES
rafa@23401
   326
            (
rafa@23401
   327
              v_NextNo, CUR_PL_Post.M_ProductionLine_ID, CUR_PL_Post.AD_Client_ID, CUR_PL_Post.AD_Org_ID,
rafa@23401
   328
              'Y', now(), v_User_ID, now(),
rafa@23401
   329
              v_User_ID, 'P+', CUR_PL_Post.M_Locator_ID, CUR_PL_Post.M_Product_ID,
rafa@23401
   330
              COALESCE(CUR_PL_Post.M_AttributeSetInstance_ID, '0'), -- not distinguishing between assemby/disassembly
rafa@23401
   331
              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
rafa@23401
   332
            )
rafa@23401
   333
            ;
rafa@23401
   334
          END IF;
gorkaion@239
   335
        IF(CUR_PL_Post.IsStocked<>'N') THEN
javier@14281
   336
          M_Check_Stock(CUR_PL_Post.M_Product_ID, v_Client_ID, v_AD_Org_ID, v_Result, v_Message) ;
sivaraman@6775
   337
          IF (v_Result=0) THEN
sivaraman@6775
   338
            v_Message:=v_Message || ' @Inline@ ' || CUR_PL_Post.line;
sivaraman@6775
   339
            RAISE_APPLICATION_ERROR(-20000, v_Message);
sivaraman@6775
   340
          END IF;
carlos@0
   341
        END IF;
carlos@0
   342
      END LOOP;
carlos@0
   343
    END IF; --FINISH_PROCESS
gorkaion@17203
   344
    IF (NOT FINISH_PROCESS) THEN
carlos@0
   345
        --Calculate Production Cost
gorkaion@17203
   346
      SELECT count(1) INTO v_count
gorkaion@17203
   347
      FROM DUAL
naiara@17411
   348
      WHERE EXISTS (SELECT 1 FROM ad_preference
naiara@17411
   349
                      WHERE attribute = 'Cost_Eng_Ins_Migrated');
gorkaion@17203
   350
      IF (v_count = 0) THEN
gorkaion@17203
   351
        --Only calculate cost automatically if legacy cost engine is used.
carlos@0
   352
        Ma_Production_Cost(v_Record_ID, v_User_ID, v_Message);
gorkaion@17203
   353
      END IF;
carlos@0
   354
    END IF; --FINISH_PROCESS
carlos@0
   355
    IF(NOT FINISH_PROCESS) THEN
carlos@0
   356
      -- Update donequantity on workrequirements
carlos@0
   357
      v_ResultStr:='Updating workrequirement';
carlos@0
   358
      FOR Cur_ProductionPlan IN
carlos@0
   359
        (SELECT *  FROM M_PRODUCTIONPLAN pp  WHERE pp.M_PRODUCTION_ID=v_Record_ID)
carlos@0
   360
      LOOP
carlos@0
   361
        UPDATE MA_WRPHASE
rdm@14983
   362
          SET DONEQUANTITY=DONEQUANTITY + Cur_ProductionPlan.PRODUCTIONQTY, RUNTIME=Cur_ProductionPlan.RUNTIME
carlos@0
   363
        WHERE MA_WRPhase_ID=Cur_ProductionPlan.MA_WRPHASE_ID;
rdm@14983
   364
        -- Close Phase if its marked
rdm@14983
   365
	IF (Cur_ProductionPlan.CLOSEPHASE='Y') THEN
rdm@14983
   366
	  v_AD_Pinstance_ID := GET_UUID();
rdm@14983
   367
	  INSERT INTO AD_PINSTANCE 
rdm@14983
   368
	  (AD_PINSTANCE_ID, AD_PROCESS_ID, RECORD_ID, ISACTIVE, 
rdm@14983
   369
	  AD_USER_ID, AD_CLIENT_ID, AD_ORG_ID, CREATED, CREATEDBY,
rdm@14983
   370
	  UPDATED, UPDATEDBY)
rdm@14983
   371
	  VALUES
rdm@14983
   372
	  (v_AD_Pinstance_ID,'800118',Cur_ProductionPlan.MA_WRPHASE_ID,'Y',
rdm@14983
   373
	  v_User_ID, v_Client_ID, v_Org_ID, now(), v_User_ID,
rdm@14983
   374
	  now(), v_User_ID
rdm@14983
   375
	  );
javier@15635
   376
	  MA_WRPHASE_CLOSE(v_AD_Pinstance_ID,'N');
rdm@14983
   377
	END IF;
carlos@0
   378
      END LOOP;
carlos@0
   379
      -- Indicate that we are done
carlos@0
   380
      UPDATE M_PRODUCTION
carlos@0
   381
        SET Processed='Y',
antonio@735
   382
        updated=now(),
carlos@0
   383
        updatedby=v_User_ID
rdm@14983
   384
      WHERE M_Production_ID=v_Record_ID;    
carlos@0
   385
    END IF; --FINISH_PROCESS
carlos@0
   386
    IF(NOT FINISH_PROCESS) THEN
carlos@0
   387
      v_ResultStr:='Updating used toolsets';
carlos@0
   388
      FOR Cur_Toolset IN
carlos@0
   389
        (SELECT MA_TOOLSETUSED.*
antonio@737
   390
         FROM MA_TOOLSETUSED, M_PRODUCTIONPLAN
carlos@0
   391
         WHERE MA_TOOLSETUSED.M_PRODUCTIONPLAN_ID = M_PRODUCTIONPLAN.M_PRODUCTIONPLAN_ID
carlos@0
   392
           AND M_PRODUCTIONPLAN.M_PRODUCTION_ID = v_Record_ID) LOOP
carlos@0
   393
        UPDATE MA_TOOLSET
carlos@0
   394
        SET NUMBERUSES = NUMBERUSES + Cur_Toolset.USED
carlos@0
   395
        WHERE MA_TOOLSET_ID = Cur_Toolset.MA_TOOLSET_ID;
carlos@0
   396
      END LOOP;
carlos@0
   397
    END IF;
rdm@15001
   398
rdm@15001
   399
    --MA_Workeffort_Validate - Finish Process Extension Point
rdm@15001
   400
	SELECT count(*) INTO v_count
rdm@15001
   401
	FROM DUAL
rdm@15001
   402
	where exists (select 1 from ad_ep_procedures where ad_extension_points_id = 'FF80818132FDD74F0132FDEFDF200024');
rdm@15001
   403
	IF (v_count=1) THEN
rdm@15001
   404
	  DECLARE
rdm@15001
   405
	    v_ep_instance VARCHAR2(32);
rdm@15001
   406
	    v_extension_point_id VARCHAR2(32) := 'FF80818132FDD74F0132FDEFDF200024';
rdm@15001
   407
	  BEGIN
rdm@15001
   408
	    v_ep_instance := get_uuid();
rdm@15001
   409
	    AD_EP_INSTANCE_PARA_INSERT(v_ep_instance, v_extension_point_id, 'Record_ID',
rdm@15001
   410
	      v_Record_ID, NULL, NULL, NULL, NULL, NULL, NULL);
rdm@15001
   411
	    AD_EP_INSTANCE_PARA_INSERT(v_ep_instance, v_extension_point_id, 'User',
rdm@15001
   412
	      v_User_ID, NULL, NULL, NULL, NULL, NULL, NULL);
rdm@15001
   413
	    AD_EP_INSTANCE_PARA_INSERT(v_ep_instance, v_extension_point_id, 'Message',
rdm@15001
   414
	      NULL, NULL, NULL, NULL, NULL, NULL, v_Message);
rdm@15001
   415
	    AD_EP_INSTANCE_PARA_INSERT(v_ep_instance, v_extension_point_id, 'Result',
rdm@15001
   416
	    NULL, NULL, v_Result, NULL, NULL, NULL, NULL);
rdm@15001
   417
	    AD_EXTENSION_POINT_HANDLER(v_ep_instance, v_extension_point_id);
rdm@15001
   418
	    SELECT p_number INTO v_Result
rdm@15001
   419
	    FROM ad_ep_instance_para
rdm@15001
   420
	    WHERE ad_ep_instance_id = v_ep_instance
rdm@15001
   421
	    AND parametername LIKE 'Result';	    
rdm@15001
   422
	    SELECT p_text INTO v_Message
rdm@15001
   423
	    FROM ad_ep_instance_para
rdm@15001
   424
	    WHERE ad_ep_instance_id = v_ep_instance
rdm@15001
   425
	    AND parametername LIKE 'Message';
rdm@15001
   426
		  
rdm@15001
   427
	    DELETE FROM ad_ep_instance_para
rdm@15001
   428
	    WHERE ad_ep_instance_id = v_ep_instance;
rdm@15001
   429
	  END;
rdm@15001
   430
	END IF;
gorkaion@239
   431
    --<<FINISH_PROCESS>>
carlos@0
   432
    --v_Message := v_Message || '@Created@: ' || v_NoRecords;
carlos@0
   433
      --  Update AD_PInstance
carlos@0
   434
      DBMS_OUTPUT.PUT_LINE('Updating PInstance - Finished ' || v_Message) ;
antonio@735
   435
      AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'N', v_Result, v_Message) ;
carlos@0
   436
    RETURN;
carlos@0
   437
  END; --BODY
carlos@0
   438
EXCEPTION
carlos@0
   439
WHEN OTHERS THEN
carlos@0
   440
  DBMS_OUTPUT.PUT_LINE(v_ResultStr) ;
carlos@0
   441
  v_ResultStr:= '@ERROR=' || SQLERRM;
carlos@0
   442
  DBMS_OUTPUT.PUT_LINE(v_ResultStr) ;
carlos@0
   443
  ROLLBACK;
antonio@735
   444
  AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'N', 0, v_ResultStr) ;
carlos@0
   445
  RETURN;
antonio@735
   446
END MA_WORKEFFORT_VALIDATE
gorkaion@239
   447
]]></body>
adrian@94
   448
    </function>
adrian@94
   449
  </database>