src-db/database/model/functions/M_INOUT_POST.xml
author Víctor Martínez Romanos <victor.martinez@openbravo.com>
Fri, 18 Nov 2016 14:51:11 +0100
changeset 30781 7232cc0b37a9
parent 30292 676e26599466
child 30782 50698b513147
permissions -rw-r--r--
Fixes issue 34612: Performance problem in Return To Vendor Shipment

Implemented C_OrderLine.QtyDelivered for return to vendor flow. This column was used only by the sales flow. However RTV (which is just a return in a purchase flow) can be considered like a sales flow (actually we are delivering products), so it has been easily adapted.
This column is now shown in RTV lines.

Implemented C_Order.IsDelivered flag for sales orders and return to vendor flows. This column was only implemented for the following Sales orders subtypes: "On Credit Order", "POS Order" and "Warehouse Order"; now it should work fine for all the sales order (although this is not a requirement for the RTVS refactor, it has been quite easy to do it).
This column is now shown in RTV header.
juanpablo@3490
     1
<?xml version="1.0"?>
juanpablo@3490
     2
  <database name="FUNCTION M_INOUT_POST">
juanpablo@3490
     3
    <function name="M_INOUT_POST" type="NULL">
juanpablo@3490
     4
      <parameter name="p_pinstance_id" type="VARCHAR" mode="in">
juanpablo@3490
     5
        <default/>
juanpablo@3490
     6
      </parameter>
juanpablo@3490
     7
      <parameter name="p_inout_id" type="VARCHAR" mode="in">
juanpablo@3490
     8
        <default/>
juanpablo@3490
     9
      </parameter>
gorkaion@239
    10
      <body><![CDATA[/*************************************************************************
juanpablo@771
    11
  * The contents of this file are subject to the Compiere Public
juanpablo@771
    12
  * License 1.1 ("License"); You may not use this file except in
juanpablo@771
    13
  * compliance with the License. You may obtain a copy of the License in
juanpablo@771
    14
  * the legal folder of your Openbravo installation.
carlos@0
    15
  * Software distributed under the License is distributed on an
carlos@0
    16
  * "AS IS" basis, WITHOUT WARRANTY OF ANY KIND, either express or
carlos@0
    17
  * implied. See the License for the specific language governing rights
carlos@0
    18
  * and limitations under the License.
juanpablo@778
    19
  * The Original Code is  Compiere  ERP &  Business Solution
juanpablo@771
    20
  * The Initial Developer of the Original Code is Jorg Janke and ComPiere, Inc.
carlos@0
    21
  * Portions created by Jorg Janke are Copyright (C) 1999-2001 Jorg Janke,
carlos@0
    22
  * parts created by ComPiere are Copyright (C) ComPiere, Inc.;
carlos@0
    23
  * All Rights Reserved.
ggi@6702
    24
  * Contributor(s): Openbravo SLU
alvaro@28246
    25
  * Contributions are Copyright (C) 2001-2016 Openbravo, S.L.U.
juanpablo@771
    26
  *
juanpablo@771
    27
  * Specifically, this derivative work is based upon the following Compiere
juanpablo@771
    28
  * file and version.
carlos@0
    29
  *************************************************************************
carlos@0
    30
  * $Id: M_InOut_Post.sql,v 1.8 2003/09/05 04:58:06 jjanke Exp $
carlos@0
    31
  ***
carlos@0
    32
  * Title: Post M_InOut_ID
carlos@0
    33
  * Description:
carlos@0
    34
  *  Action: COmplete
carlos@0
    35
  *  - Create Transaction
carlos@0
    36
  *    (only stocked products)
carlos@0
    37
  *  - Update Inventory (QtyReserved, QtyOnHand)
carlos@0
    38
  *    (only stocked products)
carlos@0
    39
  *  - Update OrderLine (QtyDelivered)
carlos@0
    40
  *
carlos@0
    41
  *  Action: Reverse Correction
carlos@0
    42
  *  - Create Header and lines with negative Quantities (and header amounts)
carlos@0
    43
  *  - Post it
carlos@0
    44
  ************************************************************************/
carlos@0
    45
  -- Logistice
carlos@0
    46
  v_ResultStr VARCHAR2(2000):='';
carlos@0
    47
  v_Message VARCHAR2(2000):='';
gorkaion@18652
    48
  v_Message_aux VARCHAR2(2000):='';
juanpablo@1605
    49
  v_Record_ID VARCHAR2(32);
juanpablo@1605
    50
  v_User VARCHAR2(32);
harikrishnan@7227
    51
  v_PUser VARCHAR2(32);
javier@21256
    52
  v_DocStatus VARCHAR2(60);
asier@1929
    53
  v_is_included NUMBER:=0;
asier@1929
    54
  v_DocType_ID VARCHAR2(32);
gorkaion@14547
    55
  v_isreturndoctype CHAR(1);
asier@1929
    56
  v_available_period NUMBER:=0;
asier@1929
    57
  v_is_ready AD_Org.IsReady%TYPE;
asier@1929
    58
  v_is_tr_allow AD_OrgType.IsTransactionsAllowed%TYPE;
asier@1929
    59
  v_DateAcct DATE;
atul@21884
    60
  v_DateDelivered C_OrderLine.DateDelivered%TYPE;
victor@3065
    61
  v_isacctle AD_OrgType.IsAcctLegalEntity%TYPE;
victor@3065
    62
  v_org_bule_id AD_Org.AD_Org_ID%TYPE;
carlos@0
    63
  -- Parameter
carlos@0
    64
  TYPE RECORD IS REF CURSOR;
carlos@0
    65
    Cur_Parameter RECORD;
carlos@0
    66
    --
carlos@0
    67
    Cur_InOut RECORD;
carlos@0
    68
    Cur_InOutLine RECORD;
gorkaion@3170
    69
    Cur_Order RECORD;
pandeeswari@21778
    70
    Cur_OrderLine RECORD;
gaurav@22036
    71
    Cur_Lines RECORD;
alvaro@27102
    72
    Cur_Reservation RECORD;
carlos@0
    73
    --
carlos@0
    74
    v_Result NUMBER:=1;
juanpablo@1605
    75
    v_AD_Org_ID VARCHAR2(32);
pandeeswari@21373
    76
    v_Warehouse_Org VARCHAR2(32);
juanpablo@1605
    77
    v_AD_Client_ID VARCHAR2(32);
juanpablo@1605
    78
    v_NextNo VARCHAR2(32);
carlos@0
    79
    v_Qty NUMBER;
carlos@0
    80
    v_QtyPO NUMBER;
carlos@0
    81
    v_QtySO NUMBER;
carlos@0
    82
    v_QuantityOrder NUMBER;
carlos@0
    83
    v_RDocumentNo VARCHAR2(40) ;
juanpablo@1605
    84
    v_RInOut_ID VARCHAR2(32);
carlos@0
    85
    v_IsStocked NUMBER;
juanpablo@1605
    86
    v_DoctypeReversed_ID VARCHAR2(32);
carlos@0
    87
    --MODIFIED BY F.IRIAZABAL
carlos@0
    88
    v_Count NUMBER:=0;
carlos@0
    89
    v_Line VARCHAR2(10) ;
alvaro@29655
    90
    v_OrderDocumentNo C_ORDER.DocumentNo%TYPE;
alvaro@29655
    91
    v_OrderLineNo C_ORDERLINE.Line%TYPE;
gorkaion@3170
    92
    v_OrderID_old VARCHAR2(32);
carlos@0
    93
    FINISH_PROCESS BOOLEAN:=false;
harikrishnan@5580
    94
    v_Aux NUMBER;
pandeeswari@21340
    95
    v_isSoTrx CHAR(1);
ioritz@17861
    96
    v_ProductName M_Product.name%TYPE;
gorkaion@18652
    97
    v_reservation_id    VARCHAR2(32);
alvaro@28246
    98
    v_reservationstock_id    VARCHAR2(32);
pandeeswari@21353
    99
    v_M_Warehouse_ID    VARCHAR2(32);
mikel@19131
   100
    v_voidmovementdate M_Inout.MovementDate%TYPE;
mikel@19131
   101
    v_voiddate_acct M_Inout.DateAcct%TYPE;
david@19194
   102
    v_bpartner_blocked VARCHAR2(1):='N';
david@19194
   103
    v_goods_blocked VARCHAR2(1):='N';
sandra@20002
   104
    v_bpartner_name c_bpartner.name%TYPE;
david@19194
   105
    v_DocAction VARCHAR2(60);
gaurav@21852
   106
    v_voiddoccount NUMBER:=0;
mikel@19131
   107
david@22931
   108
    v_penqty NUMBER;
david@22931
   109
    v_qtysumorders NUMBER;
david@22931
   110
    v_released  NUMBER;
fernando@25185
   111
    
fernando@25185
   112
    v_bp_isactive c_bpartner.isactive%Type;
atul@25018
   113
    v_IsQtyVariable M_Product.IsQuantityVariable%TYPE;
atul@25116
   114
    v_IsReversedDoc CHAR(1);
atul@25018
   115
alvaro@28246
   116
    v_countRS NUMBER:=0;
alvaro@28246
   117
    v_R_Quantity NUMBER;
alvaro@28246
   118
    v_R_Reservedqty NUMBER;
alvaro@28246
   119
    v_RS_Quantity NUMBER;
alvaro@28246
   120
    v_RS_Releasedqty NUMBER;
alvaro@27102
   121
carlos@0
   122
  BEGIN
david@22931
   123
  
carlos@0
   124
    IF(p_PInstance_ID IS NOT NULL) THEN
carlos@0
   125
      --  Update AD_PInstance
carlos@0
   126
      DBMS_OUTPUT.PUT_LINE('Updating PInstance - Processing ' || p_PInstance_ID) ;
carlos@0
   127
      v_ResultStr:='PInstanceNotFound';
carlos@0
   128
      AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'Y', NULL, NULL) ;
carlos@0
   129
      -- Get Parameters
carlos@0
   130
      v_ResultStr:='ReadingParameters';
carlos@0
   131
      FOR Cur_Parameter IN
carlos@0
   132
        (SELECT i.Record_ID,
carlos@0
   133
          i.AD_User_ID,
carlos@0
   134
          p.ParameterName,
carlos@0
   135
          p.P_String,
carlos@0
   136
          p.P_Number,
carlos@0
   137
          p.P_Date
carlos@0
   138
        FROM AD_PInstance i
carlos@0
   139
        LEFT JOIN AD_PInstance_Para p
carlos@0
   140
          ON i.AD_PInstance_ID=p.AD_PInstance_ID
carlos@0
   141
        WHERE i.AD_PInstance_ID=p_PInstance_ID
carlos@0
   142
        ORDER BY p.SeqNo
carlos@0
   143
        )
carlos@0
   144
      LOOP
carlos@0
   145
        v_Record_ID:=Cur_Parameter.Record_ID;
carlos@0
   146
        v_User:=Cur_Parameter.AD_User_ID;
mikel@19131
   147
        IF (Cur_Parameter.parametername = 'voidedDocumentDate') THEN
mikel@19131
   148
          v_voidmovementdate := TO_DATE(Cur_Parameter.p_string, 'YYYY-MM-DD');
mikel@19131
   149
        ELSIF (Cur_Parameter.parametername = 'voidedDocumentAcctDate') THEN
mikel@19131
   150
          v_voiddate_acct := TO_DATE(Cur_Parameter.p_string, 'YYYY-MM-DD');
mikel@19131
   151
        END IF;
carlos@0
   152
      END LOOP; -- Get Parameter
carlos@0
   153
      DBMS_OUTPUT.PUT_LINE('  Record_ID=' || v_Record_ID) ;
carlos@0
   154
    ELSE
gorkaion@239
   155
      DBMS_OUTPUT.PUT_LINE('--<<M_InOut_Post>>') ;
carlos@0
   156
      v_Record_ID:=p_InOut_ID;
harikrishnan@7227
   157
      SELECT count(*),updatedby
harikrishnan@7227
   158
        INTO v_Count,v_User
rafael@5825
   159
        FROM M_InOut
harikrishnan@7227
   160
        WHERE M_InOut_ID=v_Record_ID
harikrishnan@7227
   161
        GROUP BY updatedby;
rafael@5825
   162
      IF v_Count=0 THEN
rafael@5825
   163
        FINISH_PROCESS:=true;
rafael@5825
   164
      END IF;
carlos@0
   165
    END IF;
fernando@25185
   166
    
carlos@0
   167
  BEGIN --BODY
rafael@5825
   168
  	IF(NOT FINISH_PROCESS) THEN
harikrishnan@7227
   169
  	  v_PUser:=v_User;
gaurav@21852
   170
      SELECT io.AD_Client_ID, io.AD_Org_ID, io.CreatedBy, io.C_DocType_ID, io.DateAcct, dt.isreturn, io.m_warehouse_id, io.issotrx,docaction
gaurav@21852
   171
        INTO v_AD_Client_ID, v_AD_Org_ID, v_User, v_DocType_ID, v_DateAcct, v_isreturndoctype, v_M_Warehouse_ID, v_isSoTrx,v_DocAction
gorkaion@14547
   172
        FROM M_InOut io JOIN c_doctype dt ON io.c_doctype_id = dt.c_doctype_id
gorkaion@14547
   173
        WHERE io.M_InOut_ID=v_Record_ID;
harikrishnan@7227
   174
        IF(v_PUser IS NOT NULL) THEN
harikrishnan@7227
   175
        	v_User:=v_PUser;
harikrishnan@7227
   176
        END IF;
carlos@0
   177
      SELECT count(*)
carlos@0
   178
      INTO v_Count
rafael@5825
   179
      FROM AD_CLIENTINFO
rafael@5825
   180
      WHERE AD_CLIENT_ID=v_AD_Client_ID
rafael@5825
   181
        AND CHECKINOUTORG='Y';
naiara@19828
   182
      IF (v_Count>0) THEN
rafael@5825
   183
        v_ResultStr:='CheckingRestrictions - M_INOUT ORG IS IN C_BPARTNER ORG TREE';
rafael@5825
   184
        SELECT count(*)
rafael@5825
   185
        INTO v_Count
rafael@5825
   186
        FROM M_InOut m,
rafael@5825
   187
          C_BPartner bp
rafael@5825
   188
        WHERE m.M_InOut_ID=v_Record_ID
rafael@5825
   189
          AND m.C_BPARTNER_ID=bp.C_BPARTNER_ID
rafael@5825
   190
          AND AD_IsOrgIncluded(m.AD_ORG_ID, bp.AD_ORG_ID, bp.AD_CLIENT_ID)=-1;
rafael@5825
   191
        IF v_Count>0 THEN
rafael@5825
   192
          RAISE_APPLICATION_ERROR(-20000, '@NotCorrectOrgBpartnerInout@') ;
rafael@5825
   193
        END IF;
carlos@0
   194
      END IF;
gaurav@22036
   195
       Declare
gaurav@22036
   196
       v_Message_product VARCHAR(2000) :='';
gaurav@22036
   197
       Begin
gaurav@22036
   198
          FOR Cur_Lines IN (
gaurav@22036
   199
                             SELECT M.line
gaurav@22036
   200
                             FROM M_InOut I,
gaurav@22036
   201
                                  M_InOutLine M
gaurav@22036
   202
                             WHERE I.M_InOut_ID=M.M_InOut_ID
gaurav@22036
   203
                               AND I.M_INOUT_ID=v_Record_ID
gaurav@22036
   204
                               AND (M.M_PRODUCT_ID IS NULL AND M.MOVEMENTQTY <> 0)
gaurav@22036
   205
                               ORDER BY M.line
gaurav@22036
   206
                            ) LOOP
gaurav@22036
   207
               v_Message_product:=v_Message_product||Cur_Lines.line||', ';
gaurav@22036
   208
          END LOOP;
gaurav@22036
   209
          if v_Message_product != '' then
gaurav@22036
   210
             RAISE_APPLICATION_ERROR(-20000, '@Inline@ '||v_Message_product||' '||'@ProductNullAndMovementQtyGreaterZero@') ;
gaurav@22036
   211
          end if ;
gaurav@22036
   212
	     End ;
atul@23544
   213
	     Declare
atul@23544
   214
       v_Message_Qty VARCHAR(2000) :='';
atul@23544
   215
	     BEGIN
atul@23544
   216
					FOR Cur_Lines IN (
atul@23544
   217
                             SELECT M.line
atul@23544
   218
                             FROM M_InOut I,
atul@23544
   219
                                  M_InOutLine M
atul@23544
   220
                             WHERE I.M_InOut_ID=M.M_InOut_ID
atul@23544
   221
                               AND I.M_INOUT_ID=v_Record_ID
atul@23544
   222
                               AND (M.M_PRODUCT_ID IS NOT NULL AND M.MOVEMENTQTY = 0)
atul@23544
   223
                               ORDER BY M.line
atul@23544
   224
                            ) LOOP
atul@23544
   225
          v_Message_Qty:=v_Message_Qty||Cur_Lines.line||', ';
atul@23544
   226
          END LOOP;
atul@23544
   227
          IF v_Message_Qty != '' THEN
atul@23544
   228
             RAISE_APPLICATION_ERROR(-20000, '@Inline@ '||v_Message_Qty||' '||'@ProductNotNullAndMovementQtyZero@') ;
atul@23544
   229
          END IF;
atul@23544
   230
	     End ;
atul@27706
   231
      DECLARE
atul@27706
   232
      v_Message_Inactive_Products VARCHAR(2000) :='';
atul@27706
   233
      BEGIN
atul@27706
   234
        FOR Cur_Lines IN (
atul@27706
   235
          SELECT IOL.line
atul@27706
   236
          FROM M_InOutLine IOL, M_PRODUCT P
atul@27706
   237
          WHERE IOL.M_INOUT_ID=v_Record_ID
atul@27706
   238
          AND P.M_PRODUCT_ID = IOL.M_PRODUCT_ID
atul@27706
   239
          AND IOL.M_PRODUCT_ID IS NOT NULL AND P.ISACTIVE='N'
atul@27706
   240
          ORDER BY IOL.line
atul@27706
   241
          )
atul@27706
   242
        LOOP
atul@27706
   243
          v_Message_Inactive_Products:=v_Message_Inactive_Products||Cur_Lines.line||', ';
atul@27706
   244
        END LOOP;
atul@27706
   245
        IF v_Message_Inactive_Products != '' THEN
atul@27706
   246
          RAISE_APPLICATION_ERROR(-20000, '@Inline@ '||v_Message_Inactive_Products||' '||'@InActiveProducts@') ;
atul@27706
   247
        END IF;
atul@27706
   248
      END;
atul@25116
   249
      SELECT CASE WHEN COALESCE(instr(M_INOUT.Description,'*R*:'),0) = 0 THEN 'N' ELSE 'Y' END
atul@25116
   250
            INTO v_IsReversedDoc
atul@25116
   251
            FROM M_INOUT
atul@25116
   252
            WHERE M_INOUT.M_INOUT_id = v_Record_ID;
atul@25116
   253
      -- Skip MovementQtyCheck when it is reversed document
atul@25116
   254
      if(v_isreturndoctype = 'N' AND v_isSoTrx = 'Y' and v_DocAction<>'RC' AND v_IsReversedDoc='N') then
pandeeswari@21778
   255
        v_message := null;
pandeeswari@21778
   256
        for Cur_OrderLine in (
atul@25018
   257
          select c_orderline_id, line, m_product_id
pandeeswari@21778
   258
          from m_inoutline
pandeeswari@21778
   259
          where m_inout_id = v_Record_ID
gaurav@22036
   260
          and c_orderline_id is not null
pandeeswari@21778
   261
          order by line
pandeeswari@21778
   262
        ) loop
atul@25116
   263
          select COALESCE(sum(ABS(movementqty)), 0)
pandeeswari@21778
   264
          into v_qty
pandeeswari@21778
   265
          from m_inoutline
pandeeswari@21778
   266
          where m_inout_id = v_Record_ID
pandeeswari@21778
   267
          and c_orderline_id = Cur_OrderLine.c_orderline_id;
pandeeswari@21778
   268
atul@25116
   269
          select ABS(qtyordered), (coalesce(ABS(qtydelivered), 0) + v_qty)
pandeeswari@21778
   270
          into v_QuantityOrder, v_qty
pandeeswari@21778
   271
          from c_orderline
pandeeswari@21778
   272
          where c_orderline_id = Cur_OrderLine.c_orderline_id;
pandeeswari@21778
   273
atul@25018
   274
          SELECT IsQuantityVariable INTO v_IsQtyVariable
atul@25018
   275
          FROM M_Product
atul@25018
   276
          WHERE M_Product_ID = Cur_OrderLine.M_Product_ID;
atul@25018
   277
atul@25018
   278
          IF(v_IsQtyVariable='N') THEN
atul@25018
   279
            if(v_QuantityOrder < v_qty) then
atul@25018
   280
              if v_message is null THEN
atul@25018
   281
                v_message := Cur_OrderLine.line;
atul@25018
   282
              ELSE
atul@25018
   283
                v_message := v_message || ', ' || Cur_OrderLine.line;
atul@25018
   284
              END IF;
atul@25018
   285
            end if;
atul@25018
   286
          END IF;
pandeeswari@21778
   287
        end loop;
pandeeswari@21778
   288
        if v_message is not null then
pandeeswari@21778
   289
          RAISE_APPLICATION_ERROR(-20000, '@MovementQtyCheck@'||' '||'@Inlines@'||' '||v_message);
pandeeswari@21778
   290
        end if;
pandeeswari@21778
   291
      end if;
fernando@25185
   292
    
fernando@25185
   293
    
fernando@25185
   294
    /* Check active business partner*/
fernando@25185
   295
      select bp.isactive into v_bp_isactive
fernando@25185
   296
      from m_inout io 
fernando@25185
   297
      left join c_bpartner bp on io.C_BPARTNER_ID = bp.C_BPARTNER_ID
fernando@25185
   298
      where io.M_INOUT_ID = v_Record_ID;
fernando@25185
   299
fernando@25185
   300
      IF(v_bp_isactive = 'N') THEN
fernando@25185
   301
        RAISE_APPLICATION_ERROR(-20000, '@InActiveBusinessPartner@');
fernando@25185
   302
      END IF;
pandeeswari@21778
   303
pandeeswari@21353
   304
      --Check whether warehouse belongs to the organization.
pandeeswari@21353
   305
      SELECT count(AD_ORG_ID)
pandeeswari@21353
   306
      INTO v_count
pandeeswari@21353
   307
      FROM AD_Org_Warehouse
pandeeswari@21353
   308
      WHERE M_Warehouse_ID=v_M_Warehouse_ID
pandeeswari@21353
   309
      AND AD_Org_ID = v_AD_Org_ID;
pandeeswari@21353
   310
pandeeswari@21340
   311
      IF v_count = 0 AND v_isSoTrx = 'Y' THEN
pandeeswari@21353
   312
        RAISE_APPLICATION_ERROR(-20000,'@WrongWarehouse@');
pandeeswari@21353
   313
      END IF;
pandeeswari@21353
   314
pandeeswari@21373
   315
      SELECT AD_Org_ID
pandeeswari@21373
   316
      INTO v_Warehouse_Org
pandeeswari@21373
   317
      FROM M_Warehouse
pandeeswari@21373
   318
      WHERE M_Warehouse_ID = v_M_Warehouse_ID;
pandeeswari@21373
   319
pandeeswari@21373
   320
      IF(ad_org_isinnaturaltree(v_Warehouse_Org, v_AD_Org_ID, v_AD_Client_ID) = 'N' AND v_isSoTrx = 'N') THEN
pandeeswari@21373
   321
        RAISE_APPLICATION_ERROR(-20000,'@WrongWarehouse@');
pandeeswari@21373
   322
      END IF;
pandeeswari@21373
   323
david@19194
   324
      SELECT CASE WHEN (m.ISSOTRX='Y') THEN customer_blocking ELSE vendor_blocking END, CASE WHEN (m.ISSOTRX='Y') 
david@19194
   325
      THEN so_goods_blocking ELSE po_goods_blocking END, name, DocAction
david@19194
   326
      INTO v_bpartner_blocked, v_goods_blocked, v_bpartner_name, v_DocAction
david@19194
   327
      FROM M_InOut m, C_BPartner bp
david@19194
   328
      WHERE m.c_bpartner_id = bp.c_bpartner_id
david@19194
   329
      AND m.M_InOut_ID=v_Record_ID
david@19194
   330
      AND m.C_BPARTNER_ID=bp.C_BPARTNER_ID;
david@19194
   331
      
david@19194
   332
      IF (v_DocAction = 'CO' AND v_bpartner_blocked = 'Y' AND v_goods_blocked = 'Y' AND v_isreturndoctype='N') THEN
david@19194
   333
        RAISE_APPLICATION_ERROR(-20000, '@ThebusinessPartner@'||' '|| v_bpartner_name ||' '||'@BusinessPartnerBlocked@');
david@19194
   334
      END IF;
david@19194
   335
      
rafael@5825
   336
     v_ResultStr:='CheckingRestrictions';
rafael@5825
   337
     SELECT COUNT(*)
rafael@5825
   338
     INTO v_Count
rafael@5825
   339
     FROM C_DocType,
rafael@5825
   340
          M_InOut M
rafael@5825
   341
     WHERE M_Inout_ID = v_Record_ID
rafael@5825
   342
       AND C_DocType.DocBaseType IN ('MMR', 'MMS')
rafael@5825
   343
      AND C_DocType.IsSOTrx=M.IsSOTrx
rafael@5825
   344
      AND AD_ISORGINCLUDED(m.AD_Org_ID,C_DocType.AD_Org_ID, m.AD_Client_ID) <> -1
rafael@5825
   345
       AND M.C_DOCTYPE_ID=C_DocType.C_DOCTYPE_ID;
naiara@19828
   346
        IF (v_Count=0) THEN
rafael@5825
   347
          RAISE_APPLICATION_ERROR(-20000, '@NotCorrectOrgDoctypeShipment@') ;
rafael@5825
   348
        END IF;
alvaro@29655
   349
        SELECT COUNT(*), MAX(M.line), MAX(O.documentno), Max(OL.line)
alvaro@29655
   350
        INTO v_Count, v_line, v_OrderDocumentNo, v_OrderLineNo
sanjota@29654
   351
        FROM M_InOutLine M
alvaro@29655
   352
        JOIN M_Product P
alvaro@29655
   353
        ON M.m_product_id = P.m_product_id
alvaro@29655
   354
        LEFT JOIN C_OrderLine OL
alvaro@29655
   355
        ON M.c_orderline_id = OL.c_orderline_id
alvaro@29655
   356
        LEFT JOIN C_Order O
alvaro@29655
   357
        ON OL.c_order_id = O.c_order_id
sanjota@29654
   358
        WHERE P.M_ATTRIBUTESET_ID IS NOT NULL
rafael@6091
   359
          AND (P.ATTRSETVALUETYPE IS NULL OR P.ATTRSETVALUETYPE <> 'F')
rafael@6104
   360
          AND (SELECT ISONEATTRSETVALREQUIRED FROM M_ATTRIBUTESET WHERE M_ATTRIBUTESET_ID = P.M_ATTRIBUTESET_ID) = 'Y'
rafael@5825
   361
          AND COALESCE(M.M_ATTRIBUTESETINSTANCE_ID, '0') = '0'
rafael@5825
   362
          AND M.M_INOUT_ID=v_Record_ID;
alvaro@29655
   363
        IF (v_Count <> 0) THEN
alvaro@29655
   364
          IF (v_orderDocumentNo IS NULL) THEN
alvaro@29655
   365
            RAISE_APPLICATION_ERROR(-20000, '@Inline@'||' '||v_line||' '||'@productWithoutAttributeSet@');
alvaro@29655
   366
          ELSE
alvaro@29655
   367
            RAISE_APPLICATION_ERROR(-20000, '@Inline@'||' '||v_line||' '||'@productWithoutAttributeSet@'||'. '||'@INS_POREFERENCE@'||' '||v_OrderDocumentNo||' '||'@line@'||' '||v_OrderLineNo);
alvaro@29655
   368
          END IF;
rafael@5825
   369
        END IF;
rafael@5825
   370
        SELECT COUNT(*), MAX(M.line)
rafael@5825
   371
        INTO v_Count, v_Line
rafael@5825
   372
        FROM M_InOut I,
rafael@5825
   373
          M_InOutLine M,
rafael@5825
   374
          M_AttributeSetInstance P
rafael@5825
   375
        WHERE I.M_InOut_ID=M.M_InOut_ID
rafael@5825
   376
          AND M.M_AttributeSetInstance_ID=P.M_AttributeSetInstance_ID
rafael@5825
   377
          AND P.ISLOCKED='Y'
rafael@5825
   378
          AND I.ISSOTRX='Y'
rafael@5825
   379
          AND I.M_INOUT_ID=v_Record_ID;
naiara@19828
   380
        IF (v_Count<>0) THEN
rafael@5825
   381
          RAISE_APPLICATION_ERROR(-20000, '@Inline@'||v_line||' '||'@lockedProduct@') ;
rafael@5825
   382
        END IF;
rafael@5825
   383
      -- check inout line instance location
rafael@5825
   384
        SELECT COUNT(*), MAX(M.line)
rafael@5825
   385
        INTO v_Count, v_Line
rafael@5825
   386
        FROM M_InOutLine M,
rafael@5825
   387
          M_Product P
rafael@5825
   388
        WHERE M.M_InOut_ID=v_Record_ID
rafael@5825
   389
          AND M.M_Locator_ID IS NULL
rafael@5825
   390
          AND p.m_product_id = m.m_product_id
rafael@5825
   391
          AND p.isstocked = 'Y'
rafael@5825
   392
          AND p.producttype = 'I';
naiara@19828
   393
        IF (v_Count <> 0) THEN
rafael@5825
   394
          RAISE_APPLICATION_ERROR(-20000, '@Inline@'||v_line||' '||'@InoutLineWithoutLocator@') ;
rafael@5825
   395
        END IF;	  
naiara@19828
   396
      --check if bom non-stockable is exploded
naiara@19828
   397
        SELECT COUNT(*), MAX(M.line)
naiara@19828
   398
        INTO v_Count, v_Line
naiara@19828
   399
        FROM M_InOutLine M,    
naiara@19828
   400
          M_Product P
naiara@19828
   401
        WHERE M.M_InOut_ID=v_Record_ID
naiara@19828
   402
          AND P.isBOM='Y' 
naiara@19828
   403
          AND P.isstocked='N'
naiara@19828
   404
          AND M.explode='N'
naiara@19828
   405
          AND p.m_product_id = m.m_product_id;
naiara@19828
   406
        IF (v_Count <> 0) THEN
naiara@19828
   407
          RAISE_APPLICATION_ERROR(-20000, '@Inline@'||v_line||' '||'@InoutLineNotExploded@') ;
naiara@19828
   408
        END IF;
gorkaion@14547
   409
    --Check negative quantities on return inouts
gorkaion@14547
   410
    IF (v_isreturndoctype = 'Y') THEN
gorkaion@14547
   411
      SELECT count(*) INTO v_count
gorkaion@14547
   412
      FROM m_inoutline iol JOIN c_orderline ol ON iol.c_orderline_id = ol.c_orderline_id
gorkaion@14547
   413
      WHERE iol.m_inout_id = v_record_id
gorkaion@14547
   414
        AND iol.movementqty > 0
ioritz@15868
   415
        AND canceled_inoutline_id IS NULL
gorkaion@14547
   416
        AND ol.c_order_discount_id IS NULL;
gorkaion@14547
   417
      IF (v_Count <> 0) THEN
gorkaion@14547
   418
        RAISE_APPLICATION_ERROR(-20000, '@ReturnInOutNegativeQty@');
gorkaion@14547
   419
      END IF;
gorkaion@14547
   420
    END IF;
gorkaion@20976
   421
      SELECT count(*) INTO v_count
gorkaion@20976
   422
      FROM dual
gorkaion@20976
   423
      WHERE EXISTS (
gorkaion@20976
   424
          SELECT 1
gorkaion@20976
   425
          FROM m_inoutline il JOIN m_product p ON il.m_product_id = p.m_product_id
gorkaion@20976
   426
          WHERE il.m_inout_id = v_record_id
gorkaion@20976
   427
            AND p.isgeneric = 'Y');
gorkaion@20944
   428
      IF (v_count > 0) THEN
gorkaion@20976
   429
        SELECT max(p.name) INTO v_productname
gorkaion@20976
   430
        FROM m_inoutline il JOIN m_product p ON il.m_product_id = p.m_product_id
gorkaion@20976
   431
        WHERE il.m_inout_id = v_record_id
gorkaion@20976
   432
          AND p.isgeneric = 'Y';
gorkaion@20944
   433
        RAISE_APPLICATION_ERROR(-20000, '@CannotUseGenericProduct@ ' || v_productName);
gorkaion@20944
   434
      END IF;
gorkaion@20944
   435
      
rafael@5825
   436
        -- Process Shipments
pandeeswari@19202
   437
      SELECT COUNT(*) INTO v_Aux
pandeeswari@19202
   438
      FROM M_InOutLine
pandeeswari@19202
   439
      WHERE M_InOut_ID = v_Record_ID;
pandeeswari@19202
   440
pandeeswari@19202
   441
      IF v_Aux > 0 THEN  
pandeeswari@19202
   442
        SELECT COUNT(*)
sandra@19203
   443
        INTO v_Count
pandeeswari@19202
   444
        FROM M_INOUT IO, M_INOUTLINE IOL
pandeeswari@19202
   445
        WHERE IO.M_INOUT_ID = IOL.M_INOUT_ID
eduardo@19387
   446
        AND AD_ISORGINCLUDED(IOL.AD_Org_ID, IO.AD_Org_ID, IO.AD_Client_ID) = -1
sandra@19203
   447
        AND IO.M_INOUT_ID = v_Record_ID;
eduardo@19387
   448
        IF (v_Count>0) THEN
sandra@19203
   449
          RAISE_APPLICATION_ERROR(-20000, '@NotCorrectOrgLines@') ;
pandeeswari@19202
   450
        END IF;
pandeeswari@18808
   451
      END IF;
rafael@5825
   452
      
rafael@5825
   453
      -- Check the header belongs to a organization where transactions are posible and ready to use
rafael@5825
   454
      SELECT AD_Org.IsReady, Ad_OrgType.IsTransactionsAllowed
rafael@5825
   455
      INTO v_is_ready, v_is_tr_allow
rafael@5825
   456
      FROM M_INOUT, AD_Org, AD_OrgType
rafael@5825
   457
      WHERE AD_Org.AD_Org_ID=M_INOUT.AD_Org_ID
rafael@5825
   458
      AND AD_Org.AD_OrgType_ID=AD_OrgType.AD_OrgType_ID
rafael@5825
   459
      AND M_INOUT.M_INOUT_ID=v_Record_ID;
rafael@5825
   460
      IF (v_is_ready='N') THEN
rafael@5825
   461
        RAISE_APPLICATION_ERROR(-20000, '@OrgHeaderNotReady@');
carlos@0
   462
      END IF;
rafael@5825
   463
      IF (v_is_tr_allow='N') THEN
rafael@5825
   464
        RAISE_APPLICATION_ERROR(-20000, '@OrgHeaderNotTransAllowed@');
carlos@0
   465
      END IF;
rafael@5825
   466
        
rafael@5825
   467
      SELECT AD_ORG_CHK_DOCUMENTS('M_INOUT', 'M_INOUTLINE', v_Record_ID, 'M_INOUT_ID', 'M_INOUT_ID') INTO v_is_included FROM dual;
rafael@5825
   468
      IF (v_is_included=-1) THEN
rafael@5825
   469
        RAISE_APPLICATION_ERROR(-20000, '@LinesAndHeaderDifferentLEorBU@');
carlos@0
   470
      END IF;
asier@1929
   471
      
rafael@5825
   472
      -- Check the period control is opened (only if it is legal entity with accounting)
rafael@5825
   473
      -- Gets the BU or LE of the document
rafael@5825
   474
      SELECT AD_GET_DOC_LE_BU('M_INOUT', v_Record_ID, 'M_INOUT_ID', 'LE')
rafael@5825
   475
      INTO v_org_bule_id
victor@3065
   476
      FROM DUAL;
victor@3065
   477
      
rafael@5825
   478
      SELECT AD_OrgType.IsAcctLegalEntity
rafael@5825
   479
      INTO v_isacctle
rafael@5825
   480
      FROM AD_OrgType, AD_Org
rafael@5825
   481
      WHERE AD_Org.AD_OrgType_ID = AD_OrgType.AD_OrgType_ID
rafael@5825
   482
      AND AD_Org.AD_Org_ID=v_org_bule_id;
rafael@5825
   483
      
rafael@5825
   484
      IF (v_isacctle='Y') THEN    
rafael@5825
   485
        SELECT C_CHK_OPEN_PERIOD(v_AD_Org_ID, v_DateAcct, NULL, v_DocType_ID) 
rafael@5825
   486
        INTO v_available_period
rafael@5825
   487
        FROM DUAL;
javier@20594
   488
rafael@5825
   489
        IF (v_available_period<>1) THEN
javier@20594
   490
          IF (v_docAction <> 'RC') THEN
javier@20594
   491
             RAISE_APPLICATION_ERROR(-20000, '@PeriodNotAvailable@');
javier@20594
   492
          END IF;
rafael@5825
   493
        END IF;
rafael@5825
   494
      END IF;  
rafael@5825
   495
  
rafael@5825
   496
        FOR Cur_InOut IN
rafael@5825
   497
          (SELECT *
rafael@5825
   498
          FROM M_INOUT
rafael@5825
   499
          WHERE(M_InOut_ID=v_Record_ID
rafael@5825
   500
            OR(v_Record_ID IS NULL
rafael@5825
   501
            AND DocAction='CO'))
rafael@5825
   502
            AND IsActive='Y'  FOR UPDATE
rafael@5825
   503
          )
rafael@5825
   504
        LOOP
rafael@5825
   505
          DBMS_OUTPUT.PUT_LINE('Shipment_ID=' || Cur_InOut.M_InOut_ID || ', Doc=' || Cur_InOut.DocumentNo || ', Status=' || Cur_InOut.DocStatus || ', Action=' || Cur_InOut.DocAction) ;
rafael@5825
   506
          v_ResultStr:='HeaderLoop';
rafael@5825
   507
          /**
rafael@5825
   508
          * Shipment not processed
rafael@5825
   509
          */
rafael@5825
   510
          IF(Cur_InOut.Processed='N' AND Cur_InOut.DocStatus='DR' AND Cur_InOut.DocAction='CO') THEN
rafael@5825
   511
            -- For all active shipment lines
rafael@5825
   512
            v_ResultStr:='HeaderLoop-1';
pandeeswari@19202
   513
            
rafael@5825
   514
        IF v_Aux=0 THEN
rafael@5825
   515
        RAISE_APPLICATION_ERROR(-20000, '@ReceiptWithoutLines@');
rafael@5825
   516
        END IF;
carlos@0
   517
          FOR Cur_InOutLine IN
carlos@0
   518
            (SELECT *
carlos@0
   519
            FROM M_INOUTLINE
carlos@0
   520
            WHERE M_InOut_ID=Cur_InOut.M_InOut_ID
ander@30097
   521
              AND IsActive='Y' ORDER BY line FOR UPDATE
carlos@0
   522
            )
carlos@0
   523
          LOOP
adrian@170
   524
            -- Incomming or Outgoing :1:2
carlos@0
   525
            v_Qty:=Cur_InOutLine.MovementQty;
carlos@0
   526
            v_QuantityOrder:=Cur_InOutLine.QuantityOrder;
carlos@0
   527
            IF(SUBSTR(Cur_InOut.MovementType, 2)='-') THEN
carlos@0
   528
              v_Qty:=- Cur_InOutLine.MovementQty;
carlos@0
   529
              v_QuantityOrder:=-Cur_InOutLine.QuantityOrder;
carlos@0
   530
            END IF;
victor@30781
   531
            IF(Cur_InOut.IsSOTrx='N' AND v_isreturndoctype='N') THEN
carlos@0
   532
              v_QtySO:=0;
carlos@0
   533
              v_QtyPO:=Cur_InOutLine.MovementQty;
carlos@0
   534
            ELSE
carlos@0
   535
              v_QtySO:=Cur_InOutLine.MovementQty;
carlos@0
   536
              v_QtyPO:=0;
carlos@0
   537
            END IF;
carlos@0
   538
            -- UOM Conversion
adrian@170
   539
            -- Is it a standard stocked product:3
carlos@0
   540
            SELECT COUNT(*)
carlos@0
   541
            INTO v_IsStocked
carlos@0
   542
            FROM M_PRODUCT
carlos@0
   543
            WHERE M_Product_ID=Cur_InOutLine.M_Product_ID
carlos@0
   544
              AND IsStocked='Y'
carlos@0
   545
              AND ProductType='I';
carlos@0
   546
            -- Create Transaction for stocked product
harikrishnan@8015
   547
            IF(Cur_InOutLine.M_Product_ID IS NOT NULL AND v_IsStocked=1 AND Cur_InOutLine.IsDescription <> 'Y') THEN
gorkaion@18652
   548
              IF (cur_inout.issotrx = 'Y' AND cur_inoutline.c_orderline_id IS NOT NULL AND v_qty < 0 AND cur_inoutline.canceled_inoutline_id IS NULL) THEN
gorkaion@18652
   549
                -- Manage reservations.
gorkaion@18652
   550
                SELECT count(*), max(m_reservation_id)
gorkaion@18652
   551
                  INTO v_aux, v_reservation_id
gorkaion@18652
   552
                FROM m_reservation
david@22931
   553
                WHERE c_orderline_id = cur_inoutline.c_orderline_id
david@22931
   554
                AND res_status NOT IN ('DR', 'CL');
gorkaion@18652
   555
                IF (v_aux > 1) THEN
gorkaion@18652
   556
                  RAISE_APPLICATION_ERROR(-20000, '@SOLineWithMoreThanOneOpenReservation@');
gorkaion@18652
   557
                ELSIF (v_aux = 1) THEN
gorkaion@18652
   558
                  M_RESERVATION_CONSUMPTION(v_reservation_id, cur_inoutline.m_locator_id, cur_inoutline.m_attributesetinstance_id, cur_inoutline.movementqty, v_user, v_result, v_message);
gorkaion@18652
   559
                END IF;
gorkaion@18706
   560
              ELSIF (cur_inout.issotrx = 'Y' AND cur_inoutline.c_orderline_id IS NOT NULL AND v_qty > 0 AND cur_inoutline.canceled_inoutline_id IS NOT NULL) THEN
alvaro@28246
   561
                -- Undo reservation is done when voiding shipment
alvaro@28246
   562
                SELECT count(*), max(m_reservation_id)
alvaro@28246
   563
                INTO v_aux, v_reservation_id
alvaro@28246
   564
                FROM m_reservation
alvaro@28246
   565
                WHERE c_orderline_id = cur_inoutline.c_orderline_id
alvaro@28246
   566
                AND res_status NOT IN ('DR', 'CL');
alvaro@28246
   567
                IF (v_aux > 1) THEN
alvaro@28246
   568
                  RAISE_APPLICATION_ERROR(-20000, '@SOLineWithMoreThanOneOpenReservation@');
alvaro@28246
   569
                END IF;
gorkaion@19377
   570
              ELSIF (cur_inout.issotrx = 'N' AND cur_inoutline.canceled_inoutline_id IS NULL) THEN
gorkaion@18681
   571
                -- Manage pre-reserves
gorkaion@18681
   572
                DECLARE
gorkaion@18681
   573
                  cur_reserve_stock RECORD;
gorkaion@18681
   574
                  v_pendingqty NUMBER;
gorkaion@18681
   575
                  v_qtyaux NUMBER;
gorkaion@18681
   576
                  v_res_stock_id VARCHAR2(32);
gorkaion@18681
   577
                BEGIN
gorkaion@18681
   578
                  v_pendingqty := v_qty;
gorkaion@18681
   579
                  FOR cur_reserve_stock IN (
gorkaion@18681
   580
                      SELECT rs.*
gorkaion@18681
   581
                      FROM m_reservation_stock rs JOIN m_reservation r ON rs.m_reservation_id = r.m_reservation_id
gorkaion@18681
   582
                      WHERE rs.c_orderline_id = cur_inoutline.c_orderline_id
gorkaion@18681
   583
                        AND rs.quantity <> COALESCE(rs.releasedqty, 0)
gorkaion@18681
   584
                        AND rs.m_locator_id IS NULL
gorkaion@19377
   585
                        AND r.res_status NOT IN ('DR', 'CL')
gorkaion@18681
   586
                  ) LOOP
gorkaion@18681
   587
                    v_qtyaux := LEAST(cur_reserve_stock.quantity - COALESCE(cur_reserve_stock.releasedqty, 0), v_pendingqty);
gorkaion@18681
   588
                    -- Check if exists a reserved stock for the same orderline, attributes and locator in the reservation
gorkaion@18681
   589
                    SELECT count(*), max(m_reservation_stock_id) INTO v_aux, v_res_stock_id
gorkaion@18681
   590
                    FROM m_reservation_stock
gorkaion@19377
   591
                    WHERE c_orderline_id = cur_inoutline.c_orderline_id
gorkaion@19377
   592
                      AND m_locator_id = cur_inoutline.m_locator_id
gorkaion@19377
   593
                      AND m_reservation_id = cur_reserve_stock.m_reservation_id
david@22931
   594
                      AND isallocated = cur_reserve_stock.isallocated
gorkaion@19377
   595
                      AND COALESCE(m_attributesetinstance_id, '0') = COALESCE(Cur_InOutLine.M_AttributeSetInstance_ID, '0');
gorkaion@19377
   596
                    -- Update existing prereserved stock to decrease reserved qty
gorkaion@18681
   597
                    UPDATE m_reservation_stock
gorkaion@18681
   598
                    SET quantity = quantity - v_qtyaux
gorkaion@18681
   599
                    WHERE m_reservation_stock_id = cur_reserve_stock.m_reservation_stock_id;
gorkaion@19377
   600
                    -- Insert or update reserved stock by same quantity
gorkaion@18681
   601
                    IF (v_aux > 0) THEN
gorkaion@18681
   602
                      UPDATE m_reservation_stock
gorkaion@18681
   603
                      SET quantity = quantity + v_qtyaux
gorkaion@18681
   604
                      WHERE m_reservation_stock_id = v_res_stock_id;
gorkaion@18681
   605
                    ELSE
gorkaion@18681
   606
                      INSERT INTO m_reservation_stock(
gorkaion@18681
   607
                        m_reservation_stock_id, ad_client_id, ad_org_id, isactive,
gorkaion@18681
   608
                        created, createdby, updated, updatedby,
gorkaion@18681
   609
                        m_reservation_id, m_attributesetinstance_id, m_locator_id, c_orderline_id,
gorkaion@18681
   610
                        quantity, releasedqty, isallocated
gorkaion@18681
   611
                      ) VALUES (
gorkaion@18681
   612
                        get_uuid(), cur_reserve_stock.ad_client_id, cur_reserve_stock.ad_org_id, 'Y',
gorkaion@18681
   613
                        now(), v_user, now(), v_user,
eduardo@26192
   614
                        cur_reserve_stock.m_reservation_id, coalesce(cur_inoutline.m_attributesetinstance_id,'0'), cur_inoutline.m_locator_id, cur_inoutline.c_orderline_id,
david@22931
   615
                        v_qtyaux, 0, cur_reserve_stock.isallocated
gorkaion@18681
   616
                      );
gorkaion@18681
   617
                    END IF;
gorkaion@18681
   618
                    v_pendingqty := v_pendingqty - v_qtyaux;
gorkaion@18681
   619
                    IF (v_pendingqty <= 0) THEN
gorkaion@18681
   620
                      EXIT;
gorkaion@18681
   621
                    END IF;
gorkaion@18681
   622
                  END LOOP;
gorkaion@18681
   623
                  DELETE FROM m_reservation_stock
gorkaion@18681
   624
                  WHERE c_orderline_id = cur_inoutline.c_orderline_id
gorkaion@18681
   625
                    AND quantity = 0
gorkaion@18681
   626
                    AND COALESCE(releasedqty, 0) = 0;
gorkaion@18681
   627
                END;
gorkaion@19377
   628
              ELSIF (cur_inout.issotrx = 'N' AND cur_inoutline.canceled_inoutline_id IS NOT NULL AND v_qty < 0) THEN
gorkaion@19377
   629
                -- Revert to pre-reservations
david@22931
   630
atul@24291
   631
		BEGIN
david@22931
   632
                  select  sum(iol.movementqty)
david@22931
   633
                  into v_qtysumorders
david@22931
   634
                  from m_inoutline iol
david@22931
   635
                  WHERE  iol.c_orderline_id=cur_inoutline.c_orderline_id
david@22931
   636
                  and iol.m_locator_id=cur_inoutline.m_locator_id;
david@22931
   637
david@22931
   638
                  select rs.quantity
david@22931
   639
                  into v_released
david@22931
   640
                  from m_reservation_stock rs
david@22931
   641
                  where c_orderline_id=cur_inoutline.c_orderline_id
david@22931
   642
                  and rs.m_locator_id=cur_inoutline.m_locator_id;
david@22931
   643
atul@24291
   644
                EXCEPTION
atul@24291
   645
                  WHEN NO_DATA_FOUND THEN
atul@24291
   646
                  v_qtysumorders:=0;
atul@24291
   647
                  v_released:=0;
atul@24291
   648
                END;
david@22931
   649
                  v_penqty := -v_qty - ((v_qtysumorders+(-cur_inoutline.movementqty))-v_released);
david@22931
   650
gorkaion@19377
   651
                DECLARE
gorkaion@19377
   652
                  cur_reserve_stock     RECORD;
gorkaion@19377
   653
                  v_pendingqty          NUMBER;
gorkaion@19377
   654
                  v_qtyaux              NUMBER;
gorkaion@19377
   655
                  v_res_stock_id        VARCHAR2(32);
gorkaion@19380
   656
                  v_aux_released NUMBER:= 0;
gorkaion@19377
   657
                BEGIN
david@22931
   658
                  v_pendingqty:=v_penqty;
gorkaion@19377
   659
                  FOR cur_reserve_stock IN (
gorkaion@19377
   660
                      SELECT rs.quantity, COALESCE(rs.releasedqty,0) AS releasedqty, rs.m_reservation_stock_id, rs.m_reservation_id,
david@22931
   661
                          rs.ad_org_id, rs.ad_client_id, rs.isallocated
gorkaion@19377
   662
                      FROM m_reservation_stock rs JOIN m_reservation r ON rs.m_reservation_id = r.m_reservation_id
gorkaion@19377
   663
                      WHERE rs.c_orderline_id = cur_inoutline.c_orderline_id
gorkaion@19377
   664
                        AND rs.m_locator_id = cur_inoutline.m_locator_id
gorkaion@19377
   665
                        AND r.res_status NOT IN ('DR', 'CL')
gorkaion@19377
   666
                  ) LOOP
gorkaion@19377
   667
                    v_qtyaux := LEAST((cur_reserve_stock.quantity - COALESCE(cur_reserve_stock.releasedqty, 0)), v_pendingqty);
gorkaion@19377
   668
                    v_aux_released := v_aux_released + COALESCE(cur_reserve_stock.releasedqty, 0);
gorkaion@20270
   669
                    IF (cur_reserve_stock.quantity <> COALESCE(cur_reserve_stock.releasedqty, 0)) THEN
gorkaion@20270
   670
                      -- Check if exists a prereservation for the same orderline, attributes and locator in the reservation
gorkaion@20270
   671
                      SELECT count(*), max(m_reservation_stock_id) INTO v_aux, v_res_stock_id
gorkaion@20270
   672
                      FROM m_reservation_stock
gorkaion@20270
   673
                      WHERE c_orderline_id = cur_inoutline.c_orderline_id
gorkaion@20270
   674
                        AND m_locator_id IS NULL
gorkaion@20270
   675
                        AND m_reservation_id = cur_reserve_stock.m_reservation_id;
gorkaion@20270
   676
                      -- Update existing prereserved stock to decrease reserved qty
david@22931
   677
gorkaion@19377
   678
                      UPDATE m_reservation_stock
gorkaion@20270
   679
                      SET quantity = quantity - v_qtyaux
gorkaion@20270
   680
                      WHERE m_reservation_stock_id = cur_reserve_stock.m_reservation_stock_id;
gorkaion@20270
   681
                      -- Insert or update reserved stock by same quantity
gorkaion@20270
   682
                      IF (v_aux > 0) THEN
gorkaion@20270
   683
                        UPDATE m_reservation_stock
gorkaion@20270
   684
                        SET quantity = quantity + v_qtyaux
gorkaion@20270
   685
                        WHERE m_reservation_stock_id = v_res_stock_id;
gorkaion@20270
   686
                      ELSE
gorkaion@20270
   687
                        INSERT INTO m_reservation_stock (
gorkaion@20270
   688
                          m_reservation_stock_id, ad_client_id, ad_org_id, isactive,
gorkaion@20270
   689
                          created, createdby, updated, updatedby,
gorkaion@20270
   690
                          m_reservation_id, m_attributesetinstance_id, m_locator_id, c_orderline_id,
gorkaion@20270
   691
                          quantity, releasedqty, isallocated
gorkaion@20270
   692
                        ) VALUES (
gorkaion@20270
   693
                          get_uuid(), cur_reserve_stock.ad_client_id, cur_reserve_stock.ad_org_id, 'Y',
gorkaion@20270
   694
                          now(), v_user, now(), v_user,
gorkaion@20270
   695
                          cur_reserve_stock.m_reservation_id, '0', NULL, cur_inoutline.c_orderline_id,
david@22931
   696
                          v_qtyaux, 0, cur_reserve_stock.isallocated
gorkaion@20270
   697
                        );
gorkaion@20270
   698
                      END IF;
gorkaion@20270
   699
                      v_pendingqty := v_pendingqty - v_qtyaux;
gorkaion@20270
   700
                      IF (v_pendingqty <= 0) THEN
gorkaion@20270
   701
                        EXIT;
gorkaion@20270
   702
                      END IF;
gorkaion@19377
   703
                    END IF;
gorkaion@19377
   704
                  END LOOP;
gorkaion@19377
   705
                  IF (v_pendingqty > 0 AND v_aux_released > 0) THEN
gorkaion@19377
   706
                    -- Not all quantity has been reverted to pre-reservation having released quantity.
gorkaion@19377
   707
                    RAISE_APPLICATION_ERROR(-20000, '@ReceiptVoidReleasedQtyFound@');
gorkaion@19377
   708
                  END IF;
gorkaion@19377
   709
                  DELETE FROM m_reservation_stock
gorkaion@19377
   710
                  WHERE c_orderline_id = cur_inoutline.c_orderline_id
gorkaion@19377
   711
                    AND quantity = 0
gorkaion@19377
   712
                    AND COALESCE(releasedqty, 0) = 0;
gorkaion@19377
   713
                END;
david@22931
   714
gorkaion@18652
   715
              END IF;
david@22931
   716
carlos@0
   717
              v_ResultStr:='CreateTransaction';
carlos@0
   718
              Ad_Sequence_Next('M_Transaction', Cur_InOutLine.AD_Org_ID, v_NextNo) ;
carlos@0
   719
              INSERT
carlos@0
   720
              INTO M_TRANSACTION
carlos@0
   721
                (
carlos@0
   722
                  M_Transaction_ID, M_InOutLine_ID, AD_Client_ID, AD_Org_ID,
carlos@0
   723
                  IsActive, Created, CreatedBy, Updated,
carlos@0
   724
                  UpdatedBy, MovementType, M_Locator_ID, M_Product_ID,
carlos@0
   725
                  M_AttributeSetInstance_ID, MovementDate, MovementQty, M_Product_UOM_ID,
carlos@0
   726
                  QuantityOrder, C_UOM_ID
carlos@0
   727
                )
carlos@0
   728
                VALUES
carlos@0
   729
                (
carlos@0
   730
                  v_NextNo, Cur_InOutLine.M_InOutLine_ID, Cur_InOutLine.AD_Client_ID, Cur_InOutLine.AD_Org_ID,
harikrishnan@7227
   731
                   'Y', now(), v_User, now(),
harikrishnan@7227
   732
                  v_User, Cur_InOut.MovementType, Cur_InOutLine.M_Locator_ID, Cur_InOutLine.M_Product_ID,
juanpablo@1605
   733
                  COALESCE(Cur_InOutLine.M_AttributeSetInstance_ID, '0'), Cur_InOut.MovementDate, v_Qty, Cur_InOutLine.M_Product_UOM_ID,
carlos@0
   734
                  v_QuantityOrder, Cur_InOutLine.C_UOM_ID
carlos@0
   735
                )
carlos@0
   736
                ;
carlos@0
   737
            END IF;
carlos@0
   738
            -- Create Asset
carlos@0
   739
            IF(Cur_InOutLine.M_Product_ID IS NOT NULL AND Cur_InOut.IsSOTrx='Y') THEN
antonio@735
   740
              A_ASSET_CREATE(NULL, Cur_InOutLine.M_InOutLine_ID) ;
carlos@0
   741
            END IF;
carlos@0
   742
            v_ResultStr:='UpdateOrderLine';
carlos@0
   743
            IF(Cur_InOutLine.C_OrderLine_ID IS NOT NULL) THEN
victor@30781
   744
              if(Cur_InOut.ISSOTRX='Y' OR (Cur_InOut.ISSOTRX='N' AND v_isreturndoctype='Y')) THEN
atul@21879
   745
                -- Sets DateDelivered with the recent shipment date
atul@21879
   746
                -- of the shipment/s done for the orderline.
atul@21879
   747
                SELECT MAX(M.MOVEMENTDATE) INTO v_DateDelivered
atul@21879
   748
                FROM M_INOUTLINE ML, M_INOUT M
atul@21879
   749
                WHERE ML.C_OrderLine_ID = Cur_InOutLine.C_OrderLine_ID
atul@21879
   750
                AND ML.M_INOUT_ID = M.M_INOUT_ID
atul@21879
   751
                AND M.DOCSTATUS='CO';
atul@21879
   752
              ELSE
atul@21879
   753
                v_DateDelivered := null;
atul@21879
   754
              END IF;
atul@21879
   755
atul@21879
   756
              IF(v_QtySO > 0) THEN
atul@21879
   757
                IF(v_DateDelivered IS NULL OR v_DateDelivered < Cur_InOut.MovementDate ) THEN
atul@21879
   758
                  v_DateDelivered:=Cur_InOut.MovementDate;
atul@21879
   759
                END IF;
atul@21879
   760
              END IF;
atul@21879
   761
              
carlos@0
   762
              -- stocked product
carlos@0
   763
              IF(Cur_InOutLine.M_Product_ID IS NOT NULL AND v_IsStocked=1) THEN
carlos@0
   764
                -- Update OrderLine (if C-, Qty is negative)
javier@21256
   765
                SELECT DOCSTATUS into v_DocStatus
javier@21256
   766
                FROM C_ORDER
javier@21256
   767
                WHERE C_ORDER_ID = (SELECT C_ORDER_ID
javier@21256
   768
                                    FROM C_ORDERLINE 
javier@21256
   769
                                    WHERE C_ORDERLINE_ID=Cur_InOutLine.C_OrderLine_ID);
javier@21256
   770
                IF (v_DocStatus = 'DR') THEN
javier@21256
   771
                  UPDATE C_ORDERLINE
javier@21256
   772
                    SET QtyDelivered=QtyDelivered + v_QtySO,
atul@21879
   773
                    DATEDELIVERED=(CASE WHEN (QtyDelivered + v_QtySO) > 0 THEN v_DateDelivered ELSE NULL END),
javier@21256
   774
                    Updated=now(),
javier@21256
   775
                    UpdatedBy=v_User
javier@21256
   776
                  WHERE C_OrderLine_ID=Cur_InOutLine.C_OrderLine_ID;
javier@21256
   777
                ELSE 
javier@21256
   778
                  UPDATE C_ORDERLINE
javier@21256
   779
                    SET QtyReserved=QtyReserved - v_QtyPO - v_QtySO,
atul@21879
   780
                    DATEDELIVERED=(CASE WHEN (QtyReserved - v_QtyPO - v_QtySO) > 0 THEN v_DateDelivered ELSE NULL END),
javier@21256
   781
                    QtyDelivered=QtyDelivered + v_QtySO,
javier@21256
   782
                    Updated=now(),
javier@21256
   783
                    UpdatedBy=v_User
javier@21256
   784
                   WHERE C_OrderLine_ID=Cur_InOutLine.C_OrderLine_ID;
javier@21256
   785
                END IF;
carlos@0
   786
                -- Products not stocked
carlos@0
   787
              ELSE
carlos@0
   788
                -- Update OrderLine (if C-, Qty is negative)
carlos@0
   789
                UPDATE C_ORDERLINE
carlos@0
   790
                  SET QtyDelivered=QtyDelivered + v_QtySO,
atul@21879
   791
                  DATEDELIVERED=(CASE WHEN (QtyDelivered + v_QtySO) > 0 THEN v_DateDelivered ELSE NULL END),
harikrishnan@7227
   792
                  Updated=now(),
harikrishnan@7227
   793
                  UpdatedBy=v_User
carlos@0
   794
                WHERE C_OrderLine_ID=Cur_InOutLine.C_OrderLine_ID;
carlos@0
   795
              END IF;
carlos@0
   796
            END IF;
carlos@0
   797
            IF(Cur_InOutLine.M_Product_ID IS NOT NULL AND v_IsStocked=1) THEN
david@27385
   798
              M_Check_Stock(Cur_InOutLine.M_Product_ID, v_AD_Client_ID, Cur_InOutLine.AD_Org_ID, v_Result, v_Message) ;
carlos@0
   799
              IF v_Result=0 THEN
ioritz@16496
   800
                SELECT name INTO v_ProductName FROM M_Product WHERE M_Product_id = Cur_InOutLine.M_Product_ID;
ioritz@16496
   801
			    RAISE_APPLICATION_ERROR(-20000, v_Message||' '||'@line@'||' '||Cur_InOutLine.line||', '||'@Product@'||' '||v_ProductName) ;
carlos@0
   802
              END IF;
carlos@0
   803
            END IF;
carlos@0
   804
          END LOOP; -- For all InOut Lines
victor@30781
   805
victor@30781
   806
         -- Update the C_Order.IsDelivered flag only for Sales or RTV flows
victor@30781
   807
         -- This should be extended for other flows too in the future
victor@30781
   808
         IF (v_isSoTrx='Y' OR (v_isreturndoctype='Y' AND v_isSoTrx='N')) THEN
victor@30781
   809
           FOR Cur_Order IN
victor@30781
   810
           (SELECT o.c_order_id
victor@30781
   811
            FROM C_Order o
victor@30781
   812
            WHERE EXISTS (SELECT 1
victor@30781
   813
                          FROM C_ORDERLINE ol
victor@30781
   814
                          INNER JOIN M_INOUTLINE il on (il.C_ORDERLINE_ID = ol.C_ORDERLINE_ID)
victor@30781
   815
                          WHERE ol.C_Order_ID = o.C_Order_ID
victor@30781
   816
                          AND il.m_inout_id = CUR_InOut.m_inout_id
victor@30781
   817
                          )
victor@30781
   818
           )
victor@30781
   819
           LOOP
victor@30781
   820
             IF (v_IsReversedDoc = 'N') THEN
victor@30781
   821
               -- Normal Scenario
victor@30781
   822
               UPDATE C_Order o
victor@30781
   823
               SET IsDelivered = 'Y'
victor@30781
   824
               WHERE o.c_order_id = Cur_Order.c_order_id
victor@30781
   825
               AND IsDelivered = 'N'
victor@30781
   826
               AND EXISTS (SELECT 1
victor@30781
   827
                           FROM C_ORDERLINE ol
victor@30781
   828
                           WHERE ol.C_Order_ID = o.C_Order_ID
victor@30781
   829
                           GROUP BY ol.C_Order_ID
victor@30781
   830
                           HAVING SUM(ol.QTYORDERED) = SUM(ol.QTYDELIVERED));
victor@30781
   831
             ELSIF (v_IsReversedDoc = 'Y') THEN
victor@30781
   832
               -- Void Scenario
victor@30781
   833
               UPDATE C_Order o
victor@30781
   834
               SET IsDelivered = 'N'
victor@30781
   835
               WHERE o.c_order_id = Cur_Order.c_order_id
victor@30781
   836
               AND IsDelivered = 'Y'
victor@30781
   837
               AND EXISTS (SELECT 1
victor@30781
   838
                           FROM C_ORDERLINE ol
victor@30781
   839
                           WHERE ol.C_Order_ID = o.C_Order_ID
victor@30781
   840
                           AND ol.QTYORDERED <> ol.QTYDELIVERED);
victor@30781
   841
             END IF;
victor@30781
   842
           END LOOP;
victor@30781
   843
         END IF;
victor@30781
   844
carlos@0
   845
          /*******************
carlos@0
   846
          * PO Matching
carlos@0
   847
          ******************/
carlos@0
   848
          IF(Cur_InOut.IsSOTrx='N') THEN
carlos@0
   849
            DECLARE
carlos@0
   850
              Cur_SLines RECORD;
carlos@0
   851
              Cur_ILines RECORD;
carlos@0
   852
              v_Qty NUMBER;
juanpablo@1605
   853
              v_MatchPO_ID VARCHAR2(32) ;
juanpablo@1605
   854
              v_MatchInv_ID VARCHAR2(32) ;
carlos@0
   855
            BEGIN
carlos@0
   856
              v_ResultStr:='MatchPO';
carlos@0
   857
              FOR Cur_SLines IN
carlos@0
   858
                (SELECT sl.AD_Client_ID,
carlos@0
   859
                  sl.AD_Org_ID,
carlos@0
   860
                  ol.C_OrderLine_ID,
carlos@0
   861
                  sl.M_InOutLine_ID,
carlos@0
   862
                  sl.M_Product_ID,
carlos@0
   863
                  sl.M_AttributeSetInstance_ID,
carlos@0
   864
                  sl.MovementQty,
carlos@0
   865
                  ol.QtyOrdered
carlos@0
   866
                FROM M_INOUTLINE sl,
carlos@0
   867
                  C_ORDERLINE ol
carlos@0
   868
                WHERE sl.C_OrderLine_ID=ol.C_OrderLine_ID
carlos@0
   869
                  AND sl.M_Product_ID=ol.M_Product_ID  --    AND   sl.M_AttributeSetInstance_ID=ol.M_AttributeSetInstance_ID
carlos@0
   870
                  AND sl.M_InOut_ID=Cur_InOut.M_InOut_ID
carlos@0
   871
                )
david@19206
   872
              LOOP          
david@19010
   873
mikel@19201
   874
                v_Qty:=Cur_SLines.MovementQty;
mikel@19201
   875
                --IF (ABS(Cur_SLines.MovementQty) > ABS(Cur_SLines.QtyOrdered)) THEN
mikel@19201
   876
                -- v_Qty := Cur_SLines.QtyOrdered;
mikel@19201
   877
                --END IF;
david@19010
   878
mikel@19201
   879
                  Ad_Sequence_Next('M_MatchPO', Cur_SLines.AD_Org_ID, v_MatchPO_ID) ;
mikel@19201
   880
                  -- The min qty. Modified by Ismael Ciordia
mikel@19201
   881
                  v_ResultStr:='InsertMatchPO ' || v_MatchPO_ID;
mikel@19201
   882
                  INSERT
mikel@19201
   883
                  INTO M_MATCHPO
mikel@19201
   884
                    (
mikel@19201
   885
                      M_MatchPO_ID, AD_Client_ID, AD_Org_ID, IsActive,
mikel@19201
   886
                      Created, CreatedBy, Updated, UpdatedBy,
mikel@19201
   887
                      M_InOutLine_ID, C_OrderLine_ID, M_Product_ID, DateTrx,
mikel@19201
   888
                      Qty, Processing, Processed, Posted
mikel@19201
   889
                    )
mikel@19201
   890
                    VALUES
mikel@19201
   891
                    (
mikel@19201
   892
                      v_MatchPO_ID, Cur_SLines.AD_Client_ID, Cur_SLines.AD_Org_ID, 'Y',
mikel@19201
   893
                      now(), v_User, now(), v_User,
mikel@19201
   894
                      Cur_SLines.M_InOutLine_ID, Cur_SLines.C_OrderLine_ID, Cur_SLines.M_Product_ID, now(),
mikel@19201
   895
                      v_Qty, 'N', 'Y', 'N'
mikel@19201
   896
                    )
mikel@19201
   897
                  ;
mikel@19198
   898
                  
carlos@0
   899
              END LOOP;
carlos@0
   900
              v_ResultStr:='MatchInv';
carlos@0
   901
              FOR Cur_ILines IN
carlos@0
   902
                (SELECT sl.AD_Client_ID,
carlos@0
   903
                  sl.AD_Org_ID,
carlos@0
   904
                  il.C_InvoiceLine_ID,
carlos@0
   905
                  sl.M_InOutLine_ID,
carlos@0
   906
                  sl.M_Product_ID,
carlos@0
   907
                  sl.M_AttributeSetInstance_ID,
carlos@0
   908
                  sl.MovementQty,
david@7233
   909
                  il.QTYINVOICED,
david@7233
   910
                  i.DateAcct
carlos@0
   911
                FROM M_INOUTLINE sl,
david@7233
   912
                  C_INVOICE i,
carlos@0
   913
                  C_INVOICELINE il
carlos@0
   914
                WHERE sl.M_InOutLine_ID=il.M_InOutLine_ID
carlos@0
   915
                  AND sl.M_InOut_ID=Cur_InOut.M_InOut_ID
david@7233
   916
                  AND i.C_INVOICE_ID = il.C_INVOICE_ID
carlos@0
   917
                )
carlos@0
   918
              LOOP
carlos@0
   919
                Ad_Sequence_Next('M_MatchInv', Cur_ILines.AD_Org_ID, v_MatchInv_ID) ;
carlos@0
   920
                -- The min qty. Modified by Ismael Ciordia
carlos@0
   921
                v_Qty:=Cur_ILines.MovementQty;
gorkaion@239
   922
                --IF (ABS(Cur_ILines.MovementQty) > ABS(Cur_ILines.QtyInvoiced)) THEN
carlos@0
   923
                -- v_Qty := Cur_ILines.QtyInvoiced;
carlos@0
   924
                --END IF;
carlos@0
   925
                v_ResultStr:='InsertMatchPO ' || v_MatchPO_ID;
carlos@0
   926
                INSERT
carlos@0
   927
                INTO M_MATCHINV
carlos@0
   928
                  (
carlos@0
   929
                    M_MATCHINV_ID, AD_CLIENT_ID, AD_ORG_ID, ISACTIVE,
carlos@0
   930
                    CREATED, CREATEDBY, UPDATED, UPDATEDBY,
carlos@0
   931
                    M_INOUTLINE_ID, C_INVOICELINE_ID, M_PRODUCT_ID, DATETRX,
carlos@0
   932
                    QTY, PROCESSING, PROCESSED, POSTED
carlos@0
   933
                  )
carlos@0
   934
                  VALUES
carlos@0
   935
                  (
carlos@0
   936
                    v_MatchInv_ID, Cur_ILines.AD_Client_ID, Cur_ILines.AD_Org_ID, 'Y',
harikrishnan@7227
   937
                    now(), v_User, now(), v_User,
david@7233
   938
                    Cur_ILines.M_InOutLine_ID, Cur_ILines.C_InvoiceLine_ID, Cur_ILines.M_Product_ID, Cur_ILines.DateAcct,
carlos@0
   939
                    v_Qty, 'N', 'Y', 'N'
carlos@0
   940
                  )
carlos@0
   941
                  ;
carlos@0
   942
              END LOOP;
gorkaion@24928
   943
              -- Set check price difference to true in case the receipt line has a related invoice.
gorkaion@24928
   944
              UPDATE M_TRANSACTION
gorkaion@24928
   945
              SET checkpricedifference = 'Y'
gorkaion@24928
   946
              WHERE M_INOUTLINE_ID IN (SELECT DISTINCT il.m_inoutline_id
gorkaion@24928
   947
                                       FROM m_inoutline il
gorkaion@24928
   948
                                          JOIN m_matchinv mi ON il.m_inoutline_id = mi.m_inoutline_id
gorkaion@24928
   949
                                       WHERE il.m_inout_id = Cur_InOut.M_InOut_ID);
carlos@0
   950
            END;
gorkaion@3170
   951
          ELSE
gaurav@21852
   952
            --Void document is created automatically from main document . 
gaurav@21852
   953
            --during completion of void document , we have to skip delivery rule for void document .
gaurav@21852
   954
            select COALESCE(instr(M_INOUT.Description,'*R*:'),0) 
gaurav@21852
   955
            into v_voiddoccount 
gaurav@21852
   956
            from M_INOUT
gaurav@21852
   957
            where M_INOUT.M_INOUT_id =v_Record_ID;
gaurav@21852
   958
            if v_voiddoccount = 0 then
gaurav@21852
   959
              v_ResultStr:='Check delivery rule for sales orders';
gaurav@21852
   960
              v_Message_aux:='';
gaurav@21852
   961
              v_orderid_old:='0';
gaurav@21852
   962
              FOR Cur_Order IN 
gaurav@21852
   963
                (SELECT c_order.deliveryrule, m_inoutline.line, c_order.c_order_id,
gaurav@21852
   964
                        c_order.documentno, c_orderline.line as orderline
gaurav@21852
   965
                 FROM M_InOutLine, C_Orderline, C_Order
gaurav@21852
   966
                 WHERE M_Inoutline.c_orderline_id = c_orderline.c_orderline_id
gaurav@21852
   967
                   AND c_orderline.c_order_id = c_order.c_order_id
gaurav@21852
   968
                   AND m_inoutline.m_inout_id = cur_inout.m_inout_id
gaurav@21852
   969
                   AND ((c_order.deliveryrule = 'O'
gaurav@21852
   970
                        AND EXISTS (SELECT 1 FROM C_OrderLine ol
gaurav@21852
   971
                                    WHERE ol.C_Order_ID = C_order.c_order_id
gaurav@21852
   972
                                      and ol.qtyordered > ol.qtydelivered ))
gaurav@21852
   973
                        OR (c_order.deliveryrule = 'L' 
gaurav@21852
   974
                            AND c_orderline.qtyordered > c_orderline.qtydelivered))
gaurav@21852
   975
                 ORDER BY c_order.c_order_id, c_orderline.line) LOOP
gaurav@21852
   976
                --Order lines not completely delivered with delivery rule O or L
gaurav@21852
   977
                IF (v_orderid_old <> cur_order.c_order_id OR cur_order.deliveryrule <> 'O' ) THEN
gaurav@21852
   978
                  v_Message_aux := COALESCE(v_Message_aux,'') || '@Shipment@' || ' ' || cur_inout.documentno;
gaurav@21852
   979
                  v_Message_aux := v_Message_aux || ' ' || '@line@' || ' ' || cur_order.line || ': ';
gaurav@21852
   980
                  v_Message_aux := v_Message_aux || '@SalesOrderDocumentno@' || cur_order.documentno;
gaurav@21852
   981
                  IF (cur_order.deliveryrule = 'O') THEN
gaurav@21852
   982
                    v_Message_aux := v_Message_aux || ' ' || '@notCompleteDeliveryRuleOrder@' || '<br>';
gaurav@21852
   983
                  ELSE
gaurav@21852
   984
                    v_Message_aux := v_Message_aux || ' ' || '@line@' || ' ' || cur_order.orderline;
gaurav@21852
   985
                    v_Message_aux := v_Message_aux || ' ' || '@notCompleteDeliveryRuleLine@' || '<br>';
gaurav@21852
   986
                  END IF;
gorkaion@3170
   987
                END IF;
gaurav@21852
   988
                v_orderid_old := cur_order.c_order_id;
gaurav@21852
   989
              END LOOP;
gaurav@21852
   990
              IF (v_Message_aux IS NOT NULL AND v_Message_aux <> '') THEN
gaurav@21852
   991
                RAISE_APPLICATION_ERROR(-20000, v_Message_aux);
gorkaion@3170
   992
              END IF;
gorkaion@3170
   993
            END IF;
carlos@0
   994
          END IF;
carlos@0
   995
          -- Close Shipment
carlos@0
   996
          v_ResultStr:='CloseShipment';
carlos@0
   997
          UPDATE M_INOUT
carlos@0
   998
            SET Processed='Y',
carlos@0
   999
            DocStatus='CO',
carlos@0
  1000
            DocAction='--',
mikel@19150
  1001
            Process_Goods_Java='--',
harikrishnan@7227
  1002
            Updated=now(),
harikrishnan@7227
  1003
            UpdatedBy=v_User
carlos@0
  1004
          WHERE M_INOUT.M_INOUT_ID=Cur_InOut.M_INOUT_ID;
carlos@0
  1005
          --
asier@1027
  1006
          
asier@1027
  1007
         
carlos@0
  1008
          -- Not Processed + Complete --
carlos@0
  1009
          /**
carlos@0
  1010
          * Reverse Correction
carlos@0
  1011
          */
carlos@0
  1012
        ELSIF(Cur_InOut.DocStatus='CO' AND Cur_InOut.DocAction='RC') THEN
javier@17645
  1013
          --Check if the m_inoutlines has an invoice lines related. In this case is not possible to void the m_inout.
javier@17645
  1014
	  SELECT COUNT(*)
javier@17645
  1015
          INTO v_count
javier@17645
  1016
          FROM M_INOUTLINE MIOL 
javier@17645
  1017
              JOIN C_INVOICELINE CIL ON MIOL.M_INOUTLINE_ID=CIL.M_INOUTLINE_ID 
javier@17645
  1018
              JOIN C_INVOICE CI ON CI.C_INVOICE_ID=CIL.C_INVOICE_ID
javier@17645
  1019
          WHERE M_INOUT_ID=Cur_InOut.m_inout_id
javier@17645
  1020
          AND CI.DOCSTATUS <> 'VO';
javier@17645
  1021
          IF (v_count <> 0) THEN
javier@17645
  1022
	     RAISE_APPLICATION_ERROR(-20000,'@VoidShipmentWithRelatedInvoice@');
javier@17645
  1023
          END IF;
gorkaion@5377
  1024
          --Check that there isn't any line with an invoice if the order's 
gorkaion@5377
  1025
          --invoice rule is after delivery
gorkaion@5377
  1026
          select count(*), max(line) into v_count, v_line
gorkaion@5377
  1027
          from (
gorkaion@5377
  1028
          SELECT m_inoutline.m_inoutline_id, m_inoutline.line
gorkaion@5377
  1029
          from m_inoutline, c_order, c_orderline, c_invoiceline, m_inout, c_invoice
gorkaion@5377
  1030
          where m_inoutline.c_orderline_id = c_orderline.c_orderline_id
gorkaion@5377
  1031
            and c_orderline.c_order_id = c_order.c_order_id
gorkaion@5377
  1032
            and c_orderline.c_orderline_id = c_invoiceline.c_orderline_id
gorkaion@5377
  1033
            and m_inoutline.m_inout_id = m_inout.m_inout_id
gorkaion@5377
  1034
            and c_invoiceline.c_invoice_id = c_invoice.c_invoice_id
gorkaion@5377
  1035
            and m_inout.m_inout_id = Cur_InOut.m_inout_id
gorkaion@5377
  1036
            and m_inout.issotrx = 'Y'
gorkaion@5377
  1037
            and c_order.invoicerule in ('D', 'O', 'S')
gorkaion@5377
  1038
            and c_invoice.processed='Y'
gorkaion@5377
  1039
          group by m_inoutline.m_inoutline_id, m_inoutline.line
rafael@5506
  1040
          having sum(c_invoiceline.qtyinvoiced) <> 0
gorkaion@5377
  1041
          ) a;
gorkaion@5377
  1042
          IF (v_count > 0 ) THEN
gorkaion@5377
  1043
            v_Message := '@InoutDocumentno@' || ': ' || Cur_InOut.DocumentNo || ' ' || '@line@' || ': ' || v_line || '. ';
gorkaion@5377
  1044
            v_Message := v_Message || '@VoidShipmentInvoiced@';
gorkaion@5377
  1045
            RAISE_APPLICATION_ERROR(-20000, v_Message);
gorkaion@5377
  1046
          END IF;
carlos@0
  1047
          v_ResultStr:='CreateInOut';
carlos@0
  1048
          SELECT COALESCE(C_DOCTYPE_REVERSED_ID, C_DOCTYPE_ID)
carlos@0
  1049
          INTO v_DoctypeReversed_ID
carlos@0
  1050
          FROM C_DOCTYPE
carlos@0
  1051
          WHERE C_DOCTYPE_ID=Cur_InOut.C_DocType_ID;
carlos@0
  1052
          Ad_Sequence_Next('M_InOut', Cur_InOut.M_InOut_ID, v_RInOut_ID) ; -- Get RInOut_ID
carlos@0
  1053
          Ad_Sequence_Doctype(v_DoctypeReversed_ID, Cur_InOut.M_InOut_ID, 'Y', v_RDocumentNo) ; -- Get RDocumentNo
carlos@0
  1054
          IF(v_RDocumentNo IS NULL) THEN
carlos@0
  1055
            AD_Sequence_Doc('DocumentNo_M_InOut', Cur_InOut.AD_Client_ID, 'Y', v_RDocumentNo) ;
carlos@0
  1056
          END IF;
carlos@0
  1057
          -- Indicate that it is invoiced (i.e. not printed on invoices)
carlos@0
  1058
          v_ResultStr:='SetInvoiced';
harikrishnan@7227
  1059
          UPDATE M_INOUTLINE  SET IsInvoiced='Y',Updated=now(),UpdatedBy=v_User  WHERE M_InOut_ID=Cur_InOut.M_InOut_ID;
carlos@0
  1060
          --
carlos@0
  1061
          DBMS_OUTPUT.PUT_LINE('Reverse InOut_ID=' || v_RInOut_ID || ' DocumentNo=' || v_RDocumentNo) ;
carlos@0
  1062
          v_ResultStr:='InsertInOut Reverse ' || v_RInOut_ID;
carlos@0
  1063
          INSERT
carlos@0
  1064
          INTO M_INOUT
carlos@0
  1065
            (
carlos@0
  1066
              M_InOut_ID, C_Order_ID, IsSOTrx, AD_Client_ID,
carlos@0
  1067
              AD_Org_ID, IsActive, Created, CreatedBy,
carlos@0
  1068
              Updated, UpdatedBy, DocumentNo, C_DocType_ID,
carlos@0
  1069
              Description, IsPrinted, MovementType, MovementDate,
carlos@0
  1070
              DateAcct, C_BPartner_ID, C_BPartner_Location_ID, AD_User_ID,
carlos@0
  1071
              M_Warehouse_ID, POReference, DateOrdered, DeliveryRule,
carlos@0
  1072
              FreightCostRule, FreightAmt, C_Project_ID, C_Activity_ID,
carlos@0
  1073
              C_Campaign_ID, AD_OrgTrx_ID, User1_ID, User2_ID,
eduardo@18857
  1074
              C_Costcenter_ID, A_Asset_ID,
carlos@0
  1075
              DeliveryViaRule, M_Shipper_ID, C_Charge_ID, ChargeAmt,
carlos@0
  1076
              PriorityRule, DocStatus, DocAction, Processing,
pandeeswari@22934
  1077
              Processed, ISLOGISTIC, salesrep_id, Process_Goods_Java,
pandeeswari@22934
  1078
              calculate_freight, m_freightcategory_id, freight_currency_id 
carlos@0
  1079
            )
carlos@0
  1080
            VALUES
carlos@0
  1081
            (
carlos@0
  1082
              v_RInOut_ID, Cur_InOut.C_Order_ID, Cur_InOut.IsSOTrx, Cur_InOut.AD_Client_ID,
harikrishnan@7227
  1083
              Cur_InOut.AD_Org_ID, 'Y', now(), v_User,
harikrishnan@7227
  1084
              now(), v_User, v_RDocumentNo, v_DoctypeReversed_ID,
unai@15382
  1085
               '(*R*: ' || Cur_InOut.DocumentNo || ') ' || COALESCE(TO_CHAR(Cur_InOut.Description), ''), 'N', Cur_InOut.MovementType, Cur_InOut.MovementDate,
carlos@0
  1086
              Cur_InOut.DateAcct, Cur_InOut.C_BPartner_ID, Cur_InOut.C_BPartner_Location_ID, Cur_InOut.AD_User_ID,
carlos@0
  1087
              Cur_InOut.M_Warehouse_ID, Cur_InOut.POReference, Cur_InOut.DateOrdered, Cur_InOut.DeliveryRule,
carlos@0
  1088
              Cur_InOut.FreightCostRule, Cur_InOut.FreightAmt * -1, Cur_InOut.C_Project_ID, Cur_InOut.C_Activity_ID,
carlos@0
  1089
              Cur_InOut.C_Campaign_ID, Cur_InOut.AD_OrgTrx_ID, Cur_InOut.User1_ID, Cur_InOut.User2_ID,
eduardo@18857
  1090
              Cur_InOut.C_Costcenter_ID, Cur_InOut.A_Asset_ID,
carlos@0
  1091
              Cur_InOut.DeliveryViaRule, Cur_InOut.M_Shipper_ID, Cur_InOut.C_Charge_ID, Cur_InOut.ChargeAmt * -1,
carlos@0
  1092
              Cur_InOut.PriorityRule, 'DR', 'CO', 'N',
pandeeswari@22934
  1093
               'N', Cur_InOut.islogistic, Cur_InOut.salesrep_id, 'CO',
pandeeswari@22934
  1094
              Cur_InOut.calculate_freight, Cur_InOut.m_freightcategory_id, Cur_InOut.freight_currency_id 
carlos@0
  1095
            )
carlos@0
  1096
            ;
carlos@0
  1097
          v_ResultStr:='InsertInOutLine';
carlos@0
  1098
          FOR Cur_InOutLine IN
carlos@0
  1099
            (SELECT *
carlos@0
  1100
            FROM M_INOUTLINE
carlos@0
  1101
            WHERE M_InOut_ID=Cur_InOut.M_InOut_ID
carlos@0
  1102
              AND IsActive='Y'  FOR UPDATE
carlos@0
  1103
            )
carlos@0
  1104
          LOOP
carlos@0
  1105
            -- Create InOut Line
carlos@0
  1106
            Ad_Sequence_Next('M_InOutLine', Cur_InOut.M_InOut_ID, v_NextNo) ;
carlos@0
  1107
            v_ResultStr:='CreateInOutLine';
carlos@0
  1108
            INSERT
carlos@0
  1109
            INTO M_INOUTLINE
carlos@0
  1110
              (
carlos@0
  1111
                M_InOutLine_ID, Line, M_InOut_ID, C_OrderLine_ID,
carlos@0
  1112
                AD_Client_ID, AD_Org_ID, IsActive, Created,
carlos@0
  1113
                CreatedBy, Updated, UpdatedBy, M_Product_ID,
carlos@0
  1114
                M_AttributeSetInstance_ID, C_UOM_ID, M_Locator_ID, MovementQty,
asier@799
  1115
                Description, IsInvoiced,  --MODIFIED BY F.IRIAZABAL
gorkaion@15487
  1116
                QuantityOrder, M_Product_UOM_ID, IsDescription,
eduardo@18857
  1117
                canceled_inoutline_id, A_Asset_ID, C_Project_ID, C_BPartner_ID,
naiara@19828
  1118
                User1_ID, User2_ID, C_CostCenter_ID, 
naiara@19828
  1119
                explode
carlos@0
  1120
              )
carlos@0
  1121
              VALUES
carlos@0
  1122
              (
carlos@0
  1123
                v_NextNo, Cur_InOutLine.Line, v_RInOut_ID, Cur_InOutLine.C_OrderLine_ID,
carlos@0
  1124
                Cur_InOut.AD_Client_ID, Cur_InOut.AD_Org_ID, 'Y', now(),
harikrishnan@7227
  1125
                v_User, now(), v_User, Cur_InOutLine.M_Product_ID,
carlos@0
  1126
                Cur_InOutLine.M_AttributeSetInstance_ID, Cur_InOutLine.C_UOM_ID, Cur_InOutLine.M_Locator_ID, Cur_InOutLine.MovementQty * -1,
unai@15382
  1127
                 '*R*: ' || COALESCE(TO_CHAR(Cur_InOutLine.Description), ''), Cur_InOutLine.IsInvoiced, --MODIFIED BY F.IRIAZABAL
gorkaion@15487
  1128
                Cur_InOutLine.QuantityOrder * -1, Cur_InOutLine.M_PRODUCT_UOM_ID, Cur_InOutLine.IsDescription,
eduardo@18857
  1129
                Cur_InOutLine.M_InOutLine_ID, Cur_InOutLine.A_Asset_ID, Cur_InOutLine.C_Project_ID, Cur_InOutLine.C_BPartner_ID,
naiara@19828
  1130
                Cur_InOutLine.User1_ID, Cur_InOutLine.User2_ID, Cur_InOutLine.C_CostCenter_ID, 
naiara@19828
  1131
                Cur_InOutLine.explode 
carlos@0
  1132
              )
carlos@0
  1133
              ;
pandeeswari@22049
  1134
pandeeswari@22049
  1135
            -- Create InOut acctounting dimension
pandeeswari@22049
  1136
            v_ResultStr:='CreateInOutLineAcctDimension';
pandeeswari@22049
  1137
            INSERT
pandeeswari@22049
  1138
            INTO M_INOUTLINE_ACCTDIMENSION
pandeeswari@22049
  1139
              (
pandeeswari@22049
  1140
                M_InOutLine_Acctdimension_ID, M_InOutLine_ID, Quantity,
pandeeswari@22049
  1141
                AD_Client_ID, AD_Org_ID, IsActive, Created,
pandeeswari@22049
  1142
                CreatedBy, Updated, UpdatedBy, M_Product_ID, C_BPartner_ID,
pandeeswari@22049
  1143
                C_Project_ID, C_Campaign_ID, C_Activity_ID, A_Asset_ID,
pandeeswari@22049
  1144
                User1_ID, User2_ID, C_CostCenter_ID
pandeeswari@22049
  1145
              )
pandeeswari@22052
  1146
              SELECT
pandeeswari@22052
  1147
                get_uuid(), v_NextNo, Quantity * -1,
pandeeswari@22052
  1148
                AD_Client_ID, AD_Org_ID, 'Y', now(),
pandeeswari@22052
  1149
                v_User, now(), v_User, M_Product_ID, C_BPartner_ID,
pandeeswari@22052
  1150
                C_Project_ID, C_Campaign_ID, C_Activity_ID , A_Asset_ID,
pandeeswari@22052
  1151
                User1_ID, User2_ID, C_CostCenter_ID
pandeeswari@22052
  1152
              FROM M_INOUTLINE_ACCTDIMENSION where M_INOUTLINE_ID=Cur_InOutLine.M_INOUTLINE_ID
pandeeswari@22052
  1153
              and IsActive = 'Y';
pandeeswari@22052
  1154
david@7235
  1155
            INSERT INTO M_MATCHINV
david@7235
  1156
              (M_MATCHINV_ID, AD_CLIENT_ID, AD_ORG_ID, ISACTIVE, CREATED, CREATEDBY, UPDATED, UPDATEDBY,
david@7235
  1157
              M_INOUTLINE_ID, C_INVOICELINE_ID, M_PRODUCT_ID, DATETRX, QTY, PROCESSING, PROCESSED, POSTED)
david@7235
  1158
            SELECT
david@7235
  1159
              GET_UUID(), MI.AD_CLIENT_ID, MI.AD_ORG_ID, MI.ISACTIVE, now(), '0', now(), '0',
david@7240
  1160
              v_NextNo, MI.C_INVOICELINE_ID, MI.M_PRODUCT_ID, MI.DATETRX, -MI.QTY, 'N', 'Y', 'N'
david@7235
  1161
            FROM M_MATCHINV MI
david@7235
  1162
            WHERE MI.M_INOUTLINE_ID = Cur_InOutLine.M_InOutLine_ID;
gorkaion@19377
  1163
carlos@0
  1164
          END LOOP;
carlos@0
  1165
          -- Close Order
carlos@0
  1166
          v_ResultStr:='CloseInOut';
carlos@0
  1167
          UPDATE M_INOUT
carlos@0
  1168
            SET Description=COALESCE(TO_CHAR(Description), '') || ' (*R*=' || v_RDocumentNo || ')',
carlos@0
  1169
            Processed='Y',
ainhoa@2454
  1170
            DocStatus='VO', -- it IS reversed
carlos@0
  1171
            DocAction='--',
mikel@19150
  1172
            Process_Goods_Java='--',
carlos@0
  1173
            Updated=now(),
carlos@0
  1174
            UpdatedBy=v_User
carlos@0
  1175
          WHERE M_INOUT.M_INOUT_ID=Cur_InOut.M_INOUT_ID;
unai@15382
  1176
unai@15382
  1177
	   FOR Cur_InOutLine IN
unai@15382
  1178
            (SELECT *
unai@15382
  1179
            FROM M_INOUTLINE
unai@15382
  1180
            WHERE M_InOut_ID=Cur_InOut.M_InOut_ID
unai@15382
  1181
              AND IsActive='Y'  FOR UPDATE
unai@15382
  1182
            )
unai@15382
  1183
	  LOOP
unai@15382
  1184
            UPDATE M_INOUTLINE
unai@15382
  1185
              SET Description=COALESCE(TO_CHAR(Cur_InOutLine.Description), '') || ' : *R*',
unai@15382
  1186
              Updated=now(),
unai@15382
  1187
              UpdatedBy=v_User
unai@15382
  1188
            WHERE M_INOUTLINE.M_INOUTLINE_ID=Cur_InOutLine.M_INOUTLINE_ID;
alvaro@28246
  1189
          END LOOP;
alvaro@28196
  1190
carlos@0
  1191
          -- Post Reversal
carlos@0
  1192
          v_ResultStr:='PostReversal';
mikel@19131
  1193
          -- Update reversal goods dates
mikel@19131
  1194
          IF (v_voidmovementdate IS NOT NULL) THEN
mikel@19131
  1195
            UPDATE M_INOUT SET MovementDate = v_voidmovementdate WHERE M_INOUT_ID = v_RInOut_ID;
mikel@19131
  1196
          END IF;
mikel@19131
  1197
          IF (v_voiddate_acct IS NOT NULL) THEN
mikel@19131
  1198
            UPDATE M_INOUT SET DateAcct = v_voiddate_acct WHERE M_INOUT_ID = v_RInOut_ID;
mikel@19131
  1199
          END IF;
antonio@735
  1200
          M_INOUT_POST(NULL, v_RInOut_ID) ;
alvaro@28246
  1201
alvaro@28246
  1202
          -- Undo reservation by updating completed existing one or
alvaro@28246
  1203
          -- by creating new reservation to replace closed existing one
alvaro@28246
  1204
          IF (Cur_InOut.issotrx = 'Y') THEN
alvaro@28246
  1205
            FOR Cur_Reservation IN (
alvaro@28246
  1206
              SELECT r.m_reservation_id, r.ad_client_id, r.ad_org_id,
alvaro@28246
  1207
              r.m_product_id, r.quantity, r.c_uom_id, r.c_orderline_id, r.ad_user_id,
alvaro@28246
  1208
              r.c_bpartner_id, r.m_warehouse_id, r.m_attributesetinstance_id, r.m_locator_id,
alvaro@28246
  1209
              r.reservedqty, r.res_status, r.managereservation_pe, r.reservedgoodmnt_pe,
alvaro@28246
  1210
              ol.qtyordered, sum(iol.movementqty) as movementqty
alvaro@28246
  1211
              FROM M_RESERVATION r
alvaro@28246
  1212
              JOIN C_ORDERLINE ol
alvaro@28246
  1213
              ON r.c_orderline_id = ol.c_orderline_id
alvaro@28246
  1214
              JOIN M_INOUTLINE iol
alvaro@28246
  1215
              ON ol.c_orderline_id = iol.c_orderline_id
alvaro@28246
  1216
              AND ol.m_product_id = iol.m_product_id
markmm82@30292
  1217
              JOIN C_ORDER o
markmm82@30292
  1218
              ON ol.c_order_id = o.c_order_id
alvaro@28246
  1219
              WHERE iol.m_inout_id = Cur_InOut.m_inout_id
alvaro@28246
  1220
              AND r.res_status <> 'DR'
alvaro@28246
  1221
              AND iol.movementqty > 0
alvaro@28246
  1222
              AND iol.canceled_inoutline_id IS NULL
markmm82@30292
  1223
              AND o.docstatus <> 'CL'
alvaro@28246
  1224
              AND r.created = (
alvaro@28246
  1225
                SELECT max(created)
alvaro@28246
  1226
                FROM M_RESERVATION
alvaro@28246
  1227
                WHERE c_orderline_id = r.c_orderline_id
alvaro@28246
  1228
                AND res_status <> 'DR'
alvaro@28246
  1229
              )
alvaro@28677
  1230
              GROUP BY r.m_reservation_id, r.ad_client_id, r.ad_org_id,
alvaro@28677
  1231
              r.m_product_id, r.quantity, r.c_uom_id, r.c_orderline_id, r.ad_user_id,
alvaro@28677
  1232
              r.c_bpartner_id, r.m_warehouse_id, r.m_attributesetinstance_id, r.m_locator_id,
alvaro@28677
  1233
              r.reservedqty, r.res_status, r.managereservation_pe, r.reservedgoodmnt_pe, ol.qtyordered
alvaro@28246
  1234
            )
alvaro@28677
  1235
            LOOP
alvaro@28246
  1236
alvaro@28677
  1237
              -- Get the least quantity between ordered quantity and movement quantity
alvaro@28677
  1238
              v_R_Quantity := LEAST(Cur_Reservation.qtyordered, Cur_Reservation.movementqty);
alvaro@28246
  1239
alvaro@28246
  1240
              -- If completed reservation exists already update it,
alvaro@28246
  1241
              -- otherwise create a new one with this quantity
alvaro@28246
  1242
              IF (Cur_Reservation.res_status <> 'CL') THEN
alvaro@28246
  1243
                v_reservation_id := Cur_Reservation.m_reservation_id;
alvaro@28246
  1244
                v_R_Reservedqty := Cur_Reservation.reservedqty;
alvaro@28246
  1245
              ELSE
alvaro@28246
  1246
                v_reservation_id := get_uuid();
alvaro@28246
  1247
                v_R_Reservedqty := 0;
alvaro@28246
  1248
                INSERT INTO M_RESERVATION (
alvaro@28246
  1249
                  m_reservation_id, ad_client_id, ad_org_id, isactive,
alvaro@28246
  1250
                  created, createdby, updated, updatedby,
alvaro@28246
  1251
                  m_product_id, quantity, c_uom_id, c_orderline_id,
alvaro@28246
  1252
                  ad_user_id, c_bpartner_id, m_warehouse_id, m_attributesetinstance_id, m_locator_id,
alvaro@28246
  1253
                  res_status, res_process, managereservation_pe, reservedgoodmnt_pe
alvaro@28246
  1254
                ) VALUES (
alvaro@28246
  1255
                  v_reservation_id, Cur_Reservation.ad_client_id, Cur_Reservation.ad_org_id, 'Y',
alvaro@28246
  1256
                  now(), v_user, now(), v_user,
alvaro@28246
  1257
                  Cur_Reservation.m_product_id, Cur_Reservation.qtyordered, Cur_Reservation.c_uom_id, Cur_Reservation.c_orderline_id,
alvaro@28246
  1258
                  Cur_Reservation.ad_user_id, Cur_Reservation.c_bpartner_id, Cur_Reservation.m_warehouse_id,
alvaro@28246
  1259
                  Cur_Reservation.m_attributesetinstance_id, Cur_Reservation.m_locator_id,
alvaro@28246
  1260
                  'DR', 'PR', Cur_Reservation.managereservation_pe, Cur_Reservation.reservedgoodmnt_pe
alvaro@28246
  1261
                );
alvaro@28246
  1262
                -- To avoid create a reservation with all available stock,
alvaro@28246
  1263
                -- process new reservation before creating new stock reservations
alvaro@28246
  1264
                -- and delete stock reservation created by m_reserve_stock_manual
alvaro@28246
  1265
                M_RESERVATION_POST(null, v_reservation_id, 'PR', v_user);
alvaro@28246
  1266
                UPDATE M_RESERVATION_STOCK SET releasedqty = 0 WHERE m_reservation_id = v_reservation_id;
alvaro@28246
  1267
                DELETE FROM M_RESERVATION_STOCK WHERE m_reservation_id = v_reservation_id;
alvaro@28246
  1268
              END IF;
alvaro@28246
  1269
alvaro@28246
  1270
              -- Add a reservation stock fo each related inout line
alvaro@28246
  1271
              FOR Cur_InOutLine IN (
alvaro@28246
  1272
                SELECT iol.m_locator_id, COALESCE(iol.m_attributesetinstance_id, '0') as m_attributesetinstance_id,
alvaro@28246
  1273
                sum(iol.movementqty) as movementqty
alvaro@28246
  1274
                FROM M_INOUTLINE iol
alvaro@28246
  1275
                WHERE iol.m_inout_id = Cur_InOut.m_inout_id
alvaro@28246
  1276
                AND iol.c_orderline_id = Cur_Reservation.c_orderline_id
alvaro@28246
  1277
                AND iol.m_product_id = Cur_Reservation.m_product_id
alvaro@28246
  1278
                AND iol.movementqty > 0
alvaro@28246
  1279
                AND iol.canceled_inoutline_id IS NULL
alvaro@28246
  1280
                GROUP BY iol.m_locator_id, COALESCE(iol.m_attributesetinstance_id, '0')
alvaro@28246
  1281
              )
alvaro@28246
  1282
              LOOP
alvaro@28246
  1283
alvaro@28246
  1284
                -- Check if movement quantity is less or equals than ordered quantity,
alvaro@28246
  1285
                -- if so insert a new reservation stock with movement quantity,
alvaro@28246
  1286
                -- otherwise insert a new reservation stock with pending ordered quantity
alvaro@28246
  1287
                IF (Cur_InOutLine.movementqty <= v_R_Quantity) THEN
alvaro@28246
  1288
                  v_RS_Quantity := Cur_InOutLine.movementqty;
alvaro@28246
  1289
                ELSE
alvaro@28246
  1290
                  v_RS_Quantity := v_R_Quantity;
alvaro@28246
  1291
                END IF;
alvaro@28246
  1292
                v_R_Quantity := v_R_Quantity - v_RS_Quantity;
alvaro@28246
  1293
alvaro@28246
  1294
                -- If completed reservation stock exists already update it
alvaro@28246
  1295
                -- by decreasing its releasedqty or by increasing its quantity,
alvaro@28246
  1296
                -- otherwise create a new one with this quantity
alvaro@28246
  1297
                SELECT count(*), max(rs.m_reservation_stock_id), max(rs.releasedqty)
alvaro@28246
  1298
                INTO v_countRS, v_reservationstock_id, v_RS_Releasedqty
alvaro@28246
  1299
                FROM M_RESERVATION_STOCK rs
alvaro@28246
  1300
                WHERE rs.m_reservation_id = v_reservation_id
alvaro@28246
  1301
                AND rs.m_locator_id = Cur_InOutLine.m_locator_id
alvaro@28246
  1302
                AND COALESCE(rs.m_attributesetinstance_id, '0') = Cur_InOutLine.m_attributesetinstance_id;
alvaro@28246
  1303
alvaro@28246
  1304
                IF (v_countRS > 0) THEN
alvaro@28246
  1305
                  IF (v_RS_Releasedqty > 0) THEN
alvaro@28246
  1306
                    v_RS_Releasedqty := LEAST(v_RS_Releasedqty, v_RS_Quantity);
alvaro@28246
  1307
                    UPDATE M_RESERVATION_STOCK
alvaro@28246
  1308
                    SET releasedqty = releasedqty - v_RS_Releasedqty
alvaro@28246
  1309
                    WHERE m_reservation_stock_id = v_reservationstock_id;
alvaro@28246
  1310
                    v_RS_Quantity := v_RS_Quantity - v_RS_Releasedqty;
alvaro@28246
  1311
                  END IF;
alvaro@28246
  1312
                  IF (v_RS_Quantity > 0 AND Cur_Reservation.quantity >= v_R_Reservedqty + v_RS_Quantity) THEN
alvaro@28246
  1313
                    UPDATE M_RESERVATION_STOCK
alvaro@28246
  1314
                    SET quantity = quantity + v_RS_Quantity
alvaro@28246
  1315
                    WHERE m_reservation_stock_id = v_reservationstock_id;
alvaro@28246
  1316
                    v_R_Reservedqty := v_R_Reservedqty + v_RS_Quantity;
alvaro@28246
  1317
                  END IF;
alvaro@28246
  1318
                ELSE
alvaro@28246
  1319
                  INSERT INTO M_RESERVATION_STOCK (
alvaro@28246
  1320
                    m_reservation_stock_id, ad_client_id, ad_org_id, isactive,
alvaro@28246
  1321
                    created, createdby, updated, updatedby,
alvaro@30291
  1322
                    m_reservation_id, quantity, releasedqty, isallocated,
alvaro@28246
  1323
                    m_locator_id, m_attributesetinstance_id
alvaro@28246
  1324
                  ) VALUES (
alvaro@28246
  1325
                    get_uuid(), Cur_Reservation.ad_client_id, Cur_Reservation.ad_org_id, 'Y',
alvaro@28246
  1326
                    now(), v_user, now(), v_user,
alvaro@30291
  1327
                    v_reservation_id, v_RS_Quantity, 0, 'N',
alvaro@28246
  1328
                    Cur_InOutLine.m_locator_id, Cur_InOutLine.m_attributesetinstance_id
alvaro@28246
  1329
                  );
alvaro@28246
  1330
                  v_R_Reservedqty := v_R_Reservedqty + v_RS_Quantity;
alvaro@28246
  1331
                END IF;
alvaro@28246
  1332
alvaro@28246
  1333
                -- Exit if we have reserved all pending ordered quantity
alvaro@28246
  1334
                IF (v_R_Quantity <= 0) THEN
alvaro@28246
  1335
                  EXIT;
alvaro@28246
  1336
                END IF;
alvaro@28246
  1337
alvaro@28246
  1338
              END LOOP;
alvaro@28246
  1339
            END LOOP;
alvaro@28246
  1340
          END IF;
alvaro@28246
  1341
carlos@0
  1342
          -- Indicate as Reversal Transaction
carlos@0
  1343
          v_ResultStr:='IndicateReversal';
carlos@0
  1344
          UPDATE M_INOUT
carlos@0
  1345
            SET Updated=now(),
carlos@0
  1346
            UpdatedBy=v_User,
ainhoa@2454
  1347
            DocStatus='VO' -- the reversal transaction
carlos@0
  1348
          WHERE M_InOut_ID=v_RInOut_ID;
miguel@24913
  1349
miguel@24913
  1350
          -- transactions related with original inout and with voided inout will be mark as is cost permanent
miguel@24913
  1351
          UPDATE M_TRANSACTION TRX
miguel@24913
  1352
          SET ISCOSTPERMANENT='Y'
miguel@24913
  1353
          WHERE TRX.M_INOUTLINE_ID IN (SELECT M_INOUTLINE_ID 
miguel@24913
  1354
                                       FROM M_INOUTLINE
miguel@24913
  1355
                                       WHERE (M_INOUT_ID = v_RInOut_ID 
miguel@24913
  1356
                                              OR M_INOUT_ID = Cur_InOut.m_inout_id));
carlos@0
  1357
        END IF; -- ReverseCorrection
adrianromero@7702
  1358
adrianromero@7702
  1359
        --M_Inout_Post - Finish_Process Extension Point
adrianromero@7702
  1360
        --Extension point at the end of the M_Inout_Post. It has 5 available parameters Record_ID, DocAction, User, Message and Result
adrianromero@7702
  1361
        SELECT count(*) INTO v_count
adrianromero@7702
  1362
        FROM DUAL
adrianromero@7702
  1363
        where exists (select 1 from ad_ep_procedures where ad_extension_points_id = '5A7C6972321E42C2A5A8E9D6D73E6A7C');
adrianromero@7702
  1364
        IF (v_count=1) THEN
adrianromero@7702
  1365
          DECLARE
adrianromero@7702
  1366
            v_ep_instance VARCHAR2(32);
adrianromero@7702
  1367
            v_extension_point_id VARCHAR2(32) := '5A7C6972321E42C2A5A8E9D6D73E6A7C';
adrianromero@7702
  1368
          BEGIN
adrianromero@7702
  1369
            v_ep_instance := get_uuid();
adrianromero@7702
  1370
            AD_EP_INSTANCE_PARA_INSERT(v_ep_instance, v_extension_point_id, 'Record_ID',
adrianromero@7702
  1371
              v_record_id, NULL, NULL, NULL, NULL, NULL, NULL);
adrianromero@7702
  1372
            AD_EP_INSTANCE_PARA_INSERT(v_ep_instance, v_extension_point_id, 'DocAction',
adrianromero@7702
  1373
              Cur_InOut.DocAction, NULL, NULL, NULL, NULL, NULL, NULL);
adrianromero@7702
  1374
            AD_EP_INSTANCE_PARA_INSERT(v_ep_instance, v_extension_point_id, 'User',
adrianromero@7702
  1375
              v_User, NULL, NULL, NULL, NULL, NULL, NULL);
adrianromero@7702
  1376
            AD_EP_INSTANCE_PARA_INSERT(v_ep_instance, v_extension_point_id, 'Message',
adrianromero@7702
  1377
              NULL, NULL, NULL, NULL, NULL, NULL, v_Message);
adrianromero@7702
  1378
            AD_EP_INSTANCE_PARA_INSERT(v_ep_instance, v_extension_point_id, 'Result',
adrianromero@7702
  1379
              NULL, NULL, v_Result, NULL, NULL, NULL, NULL);
adrianromero@7702
  1380
            AD_EXTENSION_POINT_HANDLER(v_ep_instance, v_extension_point_id);
adrianromero@7702
  1381
            SELECT p_number INTO v_Result
adrianromero@7702
  1382
            FROM ad_ep_instance_para
adrianromero@7702
  1383
            WHERE ad_ep_instance_id = v_ep_instance
adrianromero@7702
  1384
              AND parametername LIKE 'Result';
adrianromero@7702
  1385
            SELECT p_text INTO v_Message
adrianromero@7702
  1386
            FROM ad_ep_instance_para
adrianromero@7702
  1387
            WHERE ad_ep_instance_id = v_ep_instance
adrianromero@7702
  1388
              AND parametername LIKE 'Message';
adrianromero@7702
  1389
adrianromero@7702
  1390
            DELETE FROM ad_ep_instance_para
adrianromero@7702
  1391
            WHERE ad_ep_instance_id = v_ep_instance;
adrianromero@7702
  1392
          END;
adrianromero@7702
  1393
        END IF;
adrianromero@7702
  1394
carlos@0
  1395
      END LOOP; -- InOut Header
carlos@0
  1396
      /**
carlos@0
  1397
      * Transaction End
carlos@0
  1398
      */
carlos@0
  1399
      v_ResultStr:='Fini';
carlos@0
  1400
    END IF; --FINISH_PROCESS
gorkaion@239
  1401
    --<<FINISH_PROCESS>>
carlos@0
  1402
    IF(p_PInstance_ID IS NOT NULL) THEN
carlos@0
  1403
      --  Update AD_PInstance
carlos@0
  1404
      DBMS_OUTPUT.PUT_LINE('Updating PInstance - Finished ' || v_Message) ;
carlos@0
  1405
      AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'N', v_Result, v_Message) ;
carlos@0
  1406
    ELSE
gorkaion@239
  1407
      DBMS_OUTPUT.PUT_LINE('--<<M_InOut_Post finished>>') ;
carlos@0
  1408
    END IF;
carlos@0
  1409
    RETURN;
carlos@0
  1410
  END; --BODY
carlos@0
  1411
EXCEPTION
carlos@0
  1412
WHEN OTHERS THEN
carlos@0
  1413
  v_ResultStr:= '@ERROR=' || SQLERRM;
carlos@0
  1414
  DBMS_OUTPUT.PUT_LINE(v_ResultStr) ;
carlos@0
  1415
  IF(p_PInstance_ID IS NOT NULL) THEN
carlos@0
  1416
    ROLLBACK;
carlos@0
  1417
    AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'N', 0, v_ResultStr) ;
carlos@0
  1418
  ELSE
carlos@0
  1419
    RAISE;
carlos@0
  1420
  END IF;
carlos@0
  1421
  RETURN;
antonio@735
  1422
END M_INOUT_POST
juanpablo@3490
  1423
]]></body>
juanpablo@3490
  1424
    </function>
juanpablo@3490
  1425
  </database>