src-db/database/model/functions/M_RESERVATION_POST.xml
author Unai Martirena <unai.martirena@openbravo.com>
Thu, 26 Feb 2015 19:48:36 +0100
changeset 26090 b6c2ecaf7e1a
parent 25779 aa854421dcf5
child 27059 d759928f7271
permissions -rw-r--r--
Fixes bug 28051: Reserved qty now is correct.

In this issue 3 changes have been done:
[1]: In M_RESERVATION_POST stored procedure, when calling to AD_UPDATE_PINSTANCE an extra parameter has been added ('N'). This has been done to avoid to do a commit when working with Oracle database, because it was causing to behave different in Postgres and Oracle.
[2]: In StockReservationPickAndEditDataSource, when opening Manage Reservations P&E from Sales Order, it retrieves a Reservation related to the Order Line if it exists and it processes. This was failing in Oracle if it was already processed, so a check has been added to avoid this case.
[3]: In ManageReservationActionHandler, when clicking Done in Manage Reservation P&E, it was first reserving what the user was typing in the P&E, and if it was not processed the reservation, it was processing it. As the M_RESERVATION_POST tries always to reserve as much as possible, it was overriding the previously set amounts. In order to prevent this, now first the reservation is being processed and after that the values typed in the UI are being set to the reservation.
gorkaion@18649
     1
<?xml version="1.0"?>
gorkaion@18649
     2
  <database name="FUNCTION M_RESERVATION_POST">
gorkaion@18649
     3
    <function name="M_RESERVATION_POST" type="NULL">
gorkaion@18649
     4
      <parameter name="p_pinstance_id" type="VARCHAR" mode="in">
gorkaion@18649
     5
        <default/>
gorkaion@18649
     6
      </parameter>
gorkaion@18649
     7
      <parameter name="p_reservation_id" type="VARCHAR" mode="in">
gorkaion@18649
     8
        <default/>
gorkaion@18649
     9
      </parameter>
gorkaion@18649
    10
      <parameter name="p_resaction" type="VARCHAR" mode="in">
gorkaion@18649
    11
        <default/>
gorkaion@18649
    12
      </parameter>
gorkaion@18649
    13
      <parameter name="p_user_id" type="VARCHAR" mode="in">
gorkaion@18649
    14
        <default/>
gorkaion@18649
    15
      </parameter>
gorkaion@18649
    16
      <body><![CDATA[/*************************************************************************
gorkaion@18649
    17
* The contents of this file are subject to the Openbravo  Public  License
gorkaion@18649
    18
* Version  1.1  (the  "License"),  being   the  Mozilla   Public  License
gorkaion@18649
    19
* Version 1.1  with a permitted attribution clause; you may not  use this
gorkaion@18649
    20
* file except in compliance with the License. You  may  obtain  a copy of
gorkaion@18649
    21
* the License at http://www.openbravo.com/legal/license.html
gorkaion@18649
    22
* Software distributed under the License  is  distributed  on  an "AS IS"
gorkaion@18649
    23
* basis, WITHOUT WARRANTY OF ANY KIND, either express or implied. See the
gorkaion@18649
    24
* License for the specific  language  governing  rights  and  limitations
gorkaion@18649
    25
* under the License.
gorkaion@18649
    26
* The Original Code is Openbravo ERP.
gorkaion@18649
    27
* The Initial Developer of the Original Code is Openbravo SLU
sandra@25779
    28
* All portions are Copyright (C) 2012-2015 Openbravo SLU
gorkaion@18649
    29
* All Rights Reserved.
gorkaion@18649
    30
* Contributor(s):  ______________________________________.
gorkaion@18649
    31
************************************************************************/
gorkaion@18649
    32
  v_ResultStr       VARCHAR2(2000):='';
gorkaion@18649
    33
  v_Message         VARCHAR2(2000):='';
gorkaion@18649
    34
  v_reservation_id  VARCHAR2(32);
gorkaion@18649
    35
  v_user_id         VARCHAR2(32);
gorkaion@18663
    36
  v_Result NUMBER:=1; --  Success
gorkaion@18649
    37
  v_resaction       VARCHAR2(60);
gorkaion@18649
    38
  v_resstatus       VARCHAR2(60);
gorkaion@18649
    39
  v_newstatus       VARCHAR2(60);
gorkaion@18649
    40
  v_newaction       VARCHAR2(60);
gorkaion@18689
    41
  v_orderline_id    VARCHAR2(32);
gorkaion@18695
    42
  v_product_id      VARCHAR2(32);
gorkaion@18695
    43
  v_uom_id          VARCHAR2(32);
gorkaion@19376
    44
  v_client_id       VARCHAR2(32);
gorkaion@19376
    45
  v_org_id          VARCHAR2(32);
gorkaion@18689
    46
  v_count           NUMBER;
gorkaion@18693
    47
  v_quantity        NUMBER;
gorkaion@18693
    48
  v_reservedqty     NUMBER;
gorkaion@20940
    49
  v_productname     m_product.name%TYPE;
atul@24270
    50
  v_countlines      NUMBER;
gorkaion@18649
    51
gorkaion@18649
    52
TYPE RECORD IS REF CURSOR;
gorkaion@18649
    53
  Cur_Parameter RECORD;
gorkaion@18649
    54
gorkaion@18649
    55
BEGIN
gorkaion@18649
    56
  IF (p_PInstance_ID IS NOT NULL) THEN
gorkaion@18649
    57
    --  Update AD_PInstance
gorkaion@18649
    58
    DBMS_OUTPUT.PUT_LINE('Updating PInstance - Processing ' || p_pinstance_id) ;
gorkaion@18649
    59
    v_ResultStr:='PInstanceNotFound';
unai@26090
    60
    AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'Y', NULL, NULL, 'N') ;
gorkaion@18649
    61
    --  Get Parameters
gorkaion@18649
    62
    v_ResultStr:='ReadingParameters';
gorkaion@18649
    63
    FOR Cur_Parameter IN (
gorkaion@18649
    64
        SELECT i.record_id, i.ad_user_id, p.parametername, p.p_string, p.p_number, p.p_date
gorkaion@18649
    65
        FROM ad_pinstance i
gorkaion@18649
    66
            LEFT JOIN ad_pinstance_para p ON i.ad_pinstance_id=p.ad_pinstance_id
gorkaion@18649
    67
        WHERE i.ad_pinstance_id=p_pinstance_id
gorkaion@18649
    68
        ORDER BY p.seqno
gorkaion@18649
    69
    ) LOOP
gorkaion@18649
    70
      IF (cur_parameter.parametername = 'RES_Action') THEN
gorkaion@18649
    71
        v_resaction := cur_parameter.p_string;
gorkaion@18649
    72
      END IF;
gorkaion@18649
    73
      v_reservation_id := cur_parameter.record_id;
gorkaion@18649
    74
      v_user_id := cur_parameter.ad_user_id;
gorkaion@18649
    75
    END LOOP; --  Get Parameter
gorkaion@18649
    76
    DBMS_OUTPUT.PUT_LINE('  v_Record_ID=' || v_reservation_id) ;
gorkaion@18649
    77
  ELSE
gorkaion@18649
    78
    v_reservation_id := p_reservation_id;
gorkaion@18649
    79
    v_resaction := p_resaction;
gorkaion@18649
    80
    v_user_id := p_user_id;
gorkaion@18649
    81
  END IF;
gorkaion@18649
    82
gorkaion@18649
    83
BEGIN
gorkaion@18696
    84
  SELECT res_status, c_orderline_id, quantity, reservedqty,
gorkaion@19376
    85
        m_product_id, c_uom_id, ad_client_id, ad_org_id
gorkaion@18696
    86
    INTO v_resstatus, v_orderline_id, v_quantity, v_reservedqty,
gorkaion@19376
    87
        v_product_id, v_uom_id, v_client_id, v_org_id
gorkaion@18649
    88
  FROM m_reservation
gorkaion@18649
    89
  WHERE m_reservation_id = v_reservation_id;
gorkaion@18649
    90
  
gorkaion@20972
    91
  SELECT count(*) INTO v_count
gorkaion@20972
    92
  FROM dual
gorkaion@20972
    93
  WHERE EXISTS (
gorkaion@20972
    94
      SELECT 1
gorkaion@20972
    95
      FROM m_product p 
gorkaion@20972
    96
      WHERE p.m_product_id = v_product_id
gorkaion@20972
    97
        AND p.isgeneric = 'Y');
gorkaion@20940
    98
  IF (v_count > 0) THEN
gorkaion@20972
    99
    SELECT max(p.name) INTO v_productname
gorkaion@20972
   100
    FROM m_product p 
gorkaion@20972
   101
    WHERE p.m_product_id = v_product_id
gorkaion@20972
   102
      AND p.isgeneric = 'Y';
gorkaion@20940
   103
    RAISE_APPLICATION_ERROR(-20000, '@CannotUseGenericProduct@ ' || v_productName);
gorkaion@20940
   104
  END IF;
gorkaion@20940
   105
  
gorkaion@18649
   106
  IF (v_resaction = 'PR') THEN
gorkaion@18649
   107
  /*
gorkaion@18649
   108
    Reservation Complete Process
gorkaion@18649
   109
  */
gorkaion@18693
   110
    DECLARE
gorkaion@18693
   111
      v_sales_order_id        VARCHAR2(32);
gorkaion@18695
   112
      cur_not_available       RECORD;
gorkaion@19376
   113
      cur_prereserve          RECORD;
gorkaion@19376
   114
      cur_receipt             RECORD;
gorkaion@18693
   115
      v_linecount             NUMBER;
gorkaion@18693
   116
      v_creservedcount        NUMBER;
gorkaion@18693
   117
      v_preservedcount        NUMBER;
gorkaion@19376
   118
      v_reservedqty           NUMBER;
gorkaion@19376
   119
      v_qtytoreserve          NUMBER;
gorkaion@19376
   120
      v_aux                   NUMBER;
gorkaion@19376
   121
      v_res_stock_id          VARCHAR2(32);
gorkaion@18693
   122
    BEGIN
gorkaion@18693
   123
      IF (v_resstatus != 'DR') THEN
gorkaion@18693
   124
        RAISE_APPLICATION_ERROR(-20000, '@ActionNotSupported@');
gorkaion@18689
   125
      END IF;
gorkaion@19376
   126
      -- Convert prereservation to reserve if purchase order is receipt.
gorkaion@19376
   127
      FOR cur_prereserve IN (
gorkaion@19376
   128
          SELECT rs.m_reservation_stock_id, rs.quantity, COALESCE(rs.releasedqty, 0) AS releasedqty, rs.c_orderline_id
gorkaion@19376
   129
          FROM m_reservation_stock rs
gorkaion@19376
   130
          WHERE rs.m_reservation_id = v_reservation_id
gorkaion@19376
   131
            AND rs.quantity - COALESCE(rs.releasedqty, 0) > 0
gorkaion@19376
   132
            AND rs.c_orderline_id IS NOT NULL
gorkaion@19376
   133
      ) LOOP
gorkaion@19376
   134
        v_qtytoreserve := cur_prereserve.quantity - cur_prereserve.releasedqty;
gorkaion@19376
   135
        FOR cur_receipt IN (
gorkaion@19376
   136
            SELECT SUM(mp.qty) AS receiptqty, iol.m_locator_id,
gorkaion@19376
   137
                COALESCE(iol.m_attributesetinstance_id, '0') AS m_attributesetinstance_id
gorkaion@19376
   138
            FROM m_matchpo mp
gorkaion@19376
   139
                JOIN m_inoutline iol ON mp.m_inoutline_id = iol.m_inoutline_id
gorkaion@19376
   140
            WHERE mp.c_orderline_id = cur_prereserve.c_orderline_id
gorkaion@19376
   141
            GROUP BY iol.m_locator_id, COALESCE(iol.m_attributesetinstance_id, '0')
gorkaion@19376
   142
        ) LOOP
gorkaion@19376
   143
          SELECT SUM(rs.quantity) INTO v_reservedqty
gorkaion@19376
   144
          FROM m_reservation_stock rs
gorkaion@19376
   145
               JOIN m_reservation r ON rs.m_reservation_id = r.m_reservation_id
gorkaion@19376
   146
          WHERE rs.c_orderline_id = cur_prereserve.c_orderline_id
gorkaion@19376
   147
            AND r.res_status NOT IN ('DR', 'CL')
gorkaion@19376
   148
            AND rs.m_locator_id = cur_receipt.m_locator_id
eduardo@25778
   149
            AND rs.m_attributesetinstance_id = cur_receipt.m_attributesetinstance_id;
gorkaion@19376
   150
          IF (cur_receipt.receiptqty > v_reservedqty) THEN
gorkaion@19376
   151
            v_aux := LEAST(v_qtytoreserve, cur_receipt.receiptqty - v_reservedqty);
gorkaion@19376
   152
            -- Check if exists a reserved stock for the same orderline, attributes and locator in the reservation
gorkaion@19376
   153
            SELECT count(*), max(m_reservation_stock_id) INTO v_count, v_res_stock_id
gorkaion@19376
   154
            FROM m_reservation_stock
gorkaion@19376
   155
            WHERE c_orderline_id = cur_prereserve.c_orderline_id
gorkaion@19376
   156
              AND m_locator_id = cur_receipt.m_locator_id
gorkaion@19376
   157
              AND m_reservation_id = v_reservation_id
gorkaion@19376
   158
              AND isallocated = 'Y'
eduardo@25778
   159
              AND m_attributesetinstance_id = cur_receipt.m_attributesetinstance_id;
gorkaion@19376
   160
            -- Update existing prereserved stock to decrease reserved qty
gorkaion@19376
   161
            UPDATE m_reservation_stock
gorkaion@19376
   162
            SET quantity = quantity - v_aux
gorkaion@19376
   163
            WHERE m_reservation_stock_id = cur_prereserve.m_reservation_stock_id;
gorkaion@19376
   164
            IF (v_count > 0) THEN
gorkaion@19376
   165
              UPDATE m_reservation_stock
gorkaion@19376
   166
              SET quantity = quantity + v_aux
gorkaion@19376
   167
              WHERE m_reservation_stock_id = v_res_stock_id;
gorkaion@19376
   168
            ELSE
gorkaion@19376
   169
              -- Insert reserved stock by same quantity
gorkaion@19376
   170
              INSERT INTO m_reservation_stock(
gorkaion@19376
   171
                m_reservation_stock_id, ad_client_id, ad_org_id, isactive,
gorkaion@19376
   172
                created, createdby, updated, updatedby,
gorkaion@19376
   173
                m_reservation_id, m_attributesetinstance_id, m_locator_id, c_orderline_id,
gorkaion@19376
   174
                quantity, releasedqty, isallocated
gorkaion@19376
   175
              ) VALUES (
gorkaion@19376
   176
                get_uuid(), v_client_id, v_org_id, 'Y',
gorkaion@19376
   177
                now(), v_user_id, now(), v_user_id,
gorkaion@19376
   178
                v_reservation_id, cur_receipt.m_attributesetinstance_id, cur_receipt.m_locator_id, cur_prereserve.c_orderline_id,
gorkaion@19376
   179
                v_aux, 0, 'Y'
gorkaion@19376
   180
              );
gorkaion@19376
   181
              v_qtytoreserve := v_qtytoreserve - v_aux;
gorkaion@19376
   182
            END IF;
gorkaion@19376
   183
            IF (v_qtytoreserve = 0) THEN
gorkaion@19376
   184
              EXIT;
gorkaion@19376
   185
            END IF;
gorkaion@19376
   186
          END IF;
gorkaion@19376
   187
        END LOOP;
gorkaion@19376
   188
        DELETE FROM m_reservation_stock
gorkaion@19376
   189
        WHERE c_orderline_id = cur_prereserve.c_orderline_id
gorkaion@19376
   190
          AND quantity = 0
gorkaion@19376
   191
          AND COALESCE(releasedqty, 0) = 0;
gorkaion@19376
   192
      END LOOP;
gorkaion@18695
   193
      -- Check that stock is still available
gorkaion@18695
   194
      FOR cur_not_available IN (
gorkaion@18695
   195
        SELECT AD_COLUMN_IDENTIFIER('M_Locator', rs.m_locator_id, 'en_US') as locatorName,
gorkaion@18695
   196
               asi.description AS attributeName
gorkaion@18695
   197
        FROM m_reservation_stock rs
eduardo@25778
   198
            JOIN m_attributesetinstance asi ON rs.m_attributesetinstance_id = asi.m_attributesetinstance_id
gorkaion@18695
   199
            LEFT JOIN m_storage_detail sd ON sd.m_product_id = v_product_id
gorkaion@18695
   200
                                             AND sd.c_uom_id = v_uom_id
gorkaion@18695
   201
                                             AND sd.m_product_uom_id IS NULL
eduardo@25778
   202
                                             AND sd.m_attributesetinstance_id = rs.m_attributesetinstance_id
gorkaion@18695
   203
                                             AND sd.m_locator_id = rs.m_locator_id
eduardo@25778
   204
        WHERE rs.quantity - COALESCE(rs.releasedqty, 0) > sd.qtyonhand - sd.reservedqty
gorkaion@18695
   205
          AND rs.m_reservation_id = v_reservation_id
gorkaion@19073
   206
          AND rs.m_locator_id IS NOT NULL
gorkaion@18695
   207
      ) LOOP
gorkaion@18695
   208
        RAISE_APPLICATION_ERROR(-20000, '@NotEnoughAvailableStock@ : ' || cur_not_available.locatorName || ' - ' || cur_not_available.attributeName);
gorkaion@18695
   209
      END LOOP;
gorkaion@18695
   210
      
gorkaion@18705
   211
      -- Check that prereserved quantity is equal all lower than ordered quantity
gorkaion@18705
   212
      FOR cur_not_available IN (
gorkaion@18705
   213
          SELECT AD_COLUMN_IDENTIFIER('C_Orderline', rs.c_orderline_id, 'en_US') as orderline
gorkaion@18705
   214
          FROM m_reservation_stock rs
gorkaion@18705
   215
              JOIN c_orderline ol ON rs.c_orderline_id = ol.c_orderline_id
gorkaion@18705
   216
              LEFT JOIN (
gorkaion@18705
   217
                  -- If reservation is closed consider only converted reservations as prereserve.
gorkaion@18705
   218
                  SELECT SUM(CASE r.res_status
gorkaion@18705
   219
                             WHEN 'CL' THEN CASE WHEN rs2.m_locator_id IS NULL THEN 0
gorkaion@18705
   220
                                            ELSE rs2.quantity END
gorkaion@18705
   221
                             ELSE rs2.quantity END) as qty, rs2.c_orderline_id
gorkaion@18705
   222
                  FROM m_reservation_stock rs2
gorkaion@18705
   223
                      JOIN m_reservation r ON rs2.m_reservation_id = r.m_reservation_id
gorkaion@18705
   224
                  WHERE rs2.c_orderline_id IS NOT NULL
gorkaion@18705
   225
                    AND r.res_status NOT IN ('DR')
gorkaion@24152
   226
                    AND r.m_product_id = v_product_id
gorkaion@24152
   227
                    AND r.c_uom_id = v_uom_id
gorkaion@18705
   228
                  GROUP BY rs2.c_orderline_id
gorkaion@18705
   229
                ) pre ON rs.c_orderline_id = pre.c_orderline_id
gorkaion@18705
   230
          WHERE rs.m_reservation_id = v_reservation_id
gorkaion@18705
   231
            AND rs.c_orderline_id IS NOT NULL
gorkaion@18705
   232
            AND ol.qtyordered < rs.quantity + COALESCE(pre.qty, 0)
gorkaion@18705
   233
      ) LOOP
gorkaion@18705
   234
        RAISE_APPLICATION_ERROR(-20000, '@MorePrereservedQtyThanOrdered@ '||cur_not_available.orderline);
gorkaion@18705
   235
      END LOOP;
gorkaion@18705
   236
      
gorkaion@18693
   237
      IF (v_orderline_id IS NOT NULL) THEN
gorkaion@18693
   238
        SELECT count(*) INTO v_count
gorkaion@18693
   239
        FROM m_reservation
gorkaion@18693
   240
        WHERE c_orderline_id = v_orderline_id
gorkaion@18693
   241
          AND m_reservation_id != v_reservation_id;
gorkaion@18693
   242
        IF (v_count > 0) THEN
gorkaion@18693
   243
          RAISE_APPLICATION_ERROR(-20000, '@SOLineWithMoreThanOneOpenReservation@');
gorkaion@18693
   244
        END IF;
gorkaion@18693
   245
  
gorkaion@18693
   246
        UPDATE c_orderline
gorkaion@18693
   247
        SET so_res_status = CASE WHEN v_quantity = v_reservedqty THEN 'CR'
gorkaion@18745
   248
                                 WHEN v_reservedqty > 0 THEN 'PR'
gorkaion@18745
   249
                                 ELSE 'NR'
gorkaion@18693
   250
                            END
gorkaion@18693
   251
        WHERE c_orderline_id = v_orderline_id;
gorkaion@18693
   252
  
gorkaion@18693
   253
        SELECT c_order_id INTO v_sales_order_id
gorkaion@18693
   254
        FROM c_orderline
gorkaion@18693
   255
        WHERE c_orderline_id = v_orderline_id;
gorkaion@18693
   256
        SELECT COUNT(*), SUM(CASE so_res_status WHEN 'CR' THEN 1 ELSE 0 END), SUM(CASE so_res_status WHEN 'PR' THEN 1 ELSE 0 END)
gorkaion@18693
   257
          INTO v_linecount, v_creservedcount, v_preservedcount
gorkaion@18693
   258
        FROM c_orderline
gorkaion@18693
   259
        WHERE c_order_id = v_sales_order_id;
gorkaion@18693
   260
  
gorkaion@18693
   261
        UPDATE c_order
gorkaion@18693
   262
        SET so_res_status = CASE WHEN v_linecount = v_creservedcount THEN 'CR'
gorkaion@18693
   263
                                 WHEN v_creservedcount + v_preservedcount > 0 THEN 'PR'
gorkaion@18693
   264
                                 ELSE 'NR'
gorkaion@18693
   265
                            END
gorkaion@18693
   266
        WHERE c_order_id = v_sales_order_id;
gorkaion@18693
   267
      END IF;
gorkaion@18745
   268
gorkaion@18693
   269
      v_newstatus := 'CO';
gorkaion@18693
   270
      v_newaction := 'HO';
atul@24270
   271
gorkaion@18693
   272
    END;
gorkaion@18649
   273
gorkaion@18649
   274
  ELSIF (v_resaction = 'HO') THEN
gorkaion@18649
   275
  /*
gorkaion@18649
   276
    Reservation Hold Process
gorkaion@18649
   277
  */
gorkaion@18649
   278
    IF (v_resstatus != 'CO') THEN
gorkaion@18649
   279
      RAISE_APPLICATION_ERROR(-20000, '@ActionNotSupported@');
gorkaion@18649
   280
    END IF;
gorkaion@18649
   281
    v_newstatus := 'HO';
gorkaion@18649
   282
    v_newaction := 'UNHO';
gorkaion@18649
   283
  
gorkaion@18649
   284
  
gorkaion@18649
   285
  ELSIF (v_resaction = 'UNHO') THEN
gorkaion@18649
   286
  /*
gorkaion@18649
   287
    Reservation Un-Hold Process
gorkaion@18649
   288
  */
gorkaion@18649
   289
    IF (v_resstatus != 'HO') THEN
gorkaion@18649
   290
      RAISE_APPLICATION_ERROR(-20000, '@ActionNotSupported@');
gorkaion@18649
   291
    END IF;
gorkaion@18649
   292
    v_newstatus := 'CO';
gorkaion@18649
   293
    v_newaction := 'HO';
gorkaion@18649
   294
gorkaion@18649
   295
  ELSIF (v_resaction = 'RE') THEN
gorkaion@18649
   296
  /*
gorkaion@18649
   297
    Reservation Reactivate Process
gorkaion@18649
   298
  */
gorkaion@18693
   299
    DECLARE
gorkaion@18693
   300
      v_sales_order_id        VARCHAR2(32);
gorkaion@18693
   301
      v_reservedcount         NUMBER;
gorkaion@19376
   302
      cur_prereserve          RECORD;
gorkaion@19376
   303
      v_res_stock_id          VARCHAR2(32);
gorkaion@18693
   304
    BEGIN
gorkaion@18693
   305
gorkaion@18705
   306
      IF (v_resstatus NOT IN ('CO', 'CL')) THEN
gorkaion@18693
   307
        RAISE_APPLICATION_ERROR(-20000, '@ActionNotSupported@');
gorkaion@18693
   308
      END IF;
gorkaion@18693
   309
gorkaion@18693
   310
      UPDATE c_orderline
gorkaion@18693
   311
      SET so_res_status = 'NR'
gorkaion@18693
   312
      WHERE c_orderline_id = v_orderline_id;
gorkaion@18693
   313
gorkaion@18693
   314
      SELECT c_order_id INTO v_sales_order_id
gorkaion@18693
   315
      FROM c_orderline
gorkaion@18693
   316
      WHERE c_orderline_id = v_orderline_id;
gorkaion@18693
   317
      SELECT COUNT(*) INTO v_reservedcount
gorkaion@18693
   318
      FROM c_orderline
gorkaion@18693
   319
      WHERE c_order_id = v_sales_order_id
gorkaion@18693
   320
        AND so_res_status <> 'NR';
gorkaion@19376
   321
      
gorkaion@19376
   322
      -- Convert to pre-reserve reservations related to purchase orders that are not released.
gorkaion@19376
   323
      FOR cur_prereserve IN (
gorkaion@19376
   324
          SELECT m_reservation_stock_id, quantity - COALESCE(releasedqty, 0) AS reservedqty, c_orderline_id
gorkaion@19376
   325
          FROM m_reservation_stock
gorkaion@19376
   326
          WHERE m_reservation_id = v_reservation_id
gorkaion@19376
   327
            AND c_orderline_id IS NOT NULL
gorkaion@19376
   328
            AND m_locator_id IS NOT NULL
gorkaion@19376
   329
            AND quantity - COALESCE(releasedqty, 0) > 0
gorkaion@19376
   330
      ) LOOP
gorkaion@19376
   331
        -- Check if exists a pre-reserve for the purchase order line.
gorkaion@19376
   332
        SELECT COUNT(*), MAX(m_reservation_stock_id)
gorkaion@19376
   333
          INTO v_count, v_res_stock_id
gorkaion@19376
   334
        FROM m_reservation_stock
gorkaion@19376
   335
        WHERE m_reservation_id = v_reservation_id
gorkaion@19376
   336
          AND c_orderline_id IS NOT NULL
gorkaion@19376
   337
          AND m_locator_id IS NULL;
gorkaion@19376
   338
        UPDATE m_reservation_stock
gorkaion@19376
   339
        SET quantity = quantity - cur_prereserve.reservedqty
gorkaion@19376
   340
        WHERE m_reservation_stock_id = cur_prereserve.m_reservation_stock_id;
gorkaion@19376
   341
        IF (v_count > 0) THEN
gorkaion@19376
   342
          UPDATE m_reservation_stock
gorkaion@19376
   343
          SET quantity = quantity + cur_prereserve.reservedqty
gorkaion@19376
   344
          WHERE m_reservation_stock_id = v_res_stock_id;
gorkaion@19376
   345
        ELSE
gorkaion@19376
   346
          -- Insert reserved stock by same quantity
gorkaion@19376
   347
          INSERT INTO m_reservation_stock(
gorkaion@19376
   348
            m_reservation_stock_id, ad_client_id, ad_org_id, isactive,
gorkaion@19376
   349
            created, createdby, updated, updatedby,
gorkaion@19376
   350
            m_reservation_id, m_attributesetinstance_id, m_locator_id, c_orderline_id,
gorkaion@19376
   351
            quantity, releasedqty, isallocated
gorkaion@19376
   352
          ) VALUES (
gorkaion@19376
   353
            get_uuid(), v_client_id, v_org_id, 'Y',
gorkaion@19376
   354
            now(), v_user_id, now(), v_user_id,
gorkaion@19376
   355
            v_reservation_id, '0', NULL, cur_prereserve.c_orderline_id,
gorkaion@19376
   356
            cur_prereserve.reservedqty, 0, 'Y'
gorkaion@19376
   357
          );
gorkaion@19376
   358
        END IF;
gorkaion@19376
   359
      END LOOP;
gorkaion@19376
   360
      DELETE FROM m_reservation_stock
gorkaion@19376
   361
      WHERE m_reservation_id = v_reservation_id
gorkaion@19376
   362
        AND quantity = 0
gorkaion@19376
   363
        AND COALESCE(releasedqty, 0) = 0;
gorkaion@18693
   364
gorkaion@18693
   365
      UPDATE c_order
gorkaion@18693
   366
      SET so_res_status = CASE WHEN v_reservedcount > 0 THEN 'PR'
gorkaion@18693
   367
                               ELSE 'NR'
gorkaion@18693
   368
                          END
gorkaion@18693
   369
      WHERE c_order_id = v_sales_order_id;
gorkaion@18693
   370
gorkaion@18693
   371
      v_newstatus := 'DR';
gorkaion@18693
   372
      v_newaction := 'PR';
gorkaion@18693
   373
    END;
gorkaion@18649
   374
  
gorkaion@18649
   375
  ELSIF (v_resaction = 'CL') THEN
gorkaion@18649
   376
  /*
gorkaion@18649
   377
    Reservation Close Process
gorkaion@18649
   378
  */
gorkaion@18649
   379
    IF (v_resstatus != 'CO' AND v_resstatus != 'HO') THEN
gorkaion@18649
   380
      RAISE_APPLICATION_ERROR(-20000, '@ActionNotSupported@');
gorkaion@18649
   381
    END IF;
gorkaion@18649
   382
    v_newstatus := 'CL';
gorkaion@18705
   383
    v_newaction := 'RE';
gorkaion@18649
   384
gorkaion@18649
   385
  ELSE
gorkaion@18649
   386
    RAISE_APPLICATION_ERROR(-20000, '@UnsupportedResAction@');
gorkaion@18649
   387
  END IF;
gorkaion@18649
   388
gorkaion@18649
   389
  UPDATE m_reservation
gorkaion@18649
   390
  SET res_status = v_newstatus,
gorkaion@18649
   391
      res_process = v_newaction,
gorkaion@18649
   392
      updated = now(),
gorkaion@18649
   393
      updatedby = v_user_id
gorkaion@18649
   394
  WHERE m_reservation_id = v_reservation_id;
gorkaion@18649
   395
gorkaion@21157
   396
  IF (v_resaction = 'PR') THEN
gorkaion@21157
   397
    -- ADD RESERVED STOCK
gorkaion@21157
   398
    M_RESERVE_STOCK_AUTO(v_reservation_id, v_user_id, v_message);
gorkaion@21157
   399
  END IF;
gorkaion@21157
   400
atul@24321
   401
  /* Do not process reservation's with no lines
atul@24321
   402
      */
atul@24321
   403
      v_countlines:=0;
atul@24321
   404
      SELECT COUNT(*) INTO v_countlines
atul@24321
   405
        FROM m_reservation_stock
atul@24321
   406
        WHERE m_reservation_id = v_reservation_id;
atul@24321
   407
      IF(v_countlines = 0) THEN
atul@24321
   408
        v_newstatus:='DR';
atul@24321
   409
        v_newaction:='PR';
atul@24321
   410
	UPDATE m_reservation
atul@24321
   411
          SET res_status = v_newstatus,
atul@24321
   412
              res_process = v_newaction,
atul@24321
   413
              updated = now(),
atul@24321
   414
              updatedby = v_user_id
atul@24321
   415
        WHERE m_reservation_id = v_reservation_id;
atul@24321
   416
      END IF;
atul@24321
   417
gorkaion@18649
   418
  IF (p_pinstance_id IS NOT NULL) THEN
gorkaion@18649
   419
    DBMS_OUTPUT.PUT_LINE('Updating PInstance - Finished ' || v_Message) ;
unai@26090
   420
    AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'N', v_Result, v_Message, 'N') ;
gorkaion@18649
   421
    DBMS_OUTPUT.PUT_LINE('--<<M_Reservation_Post finished>> ' || v_Message) ;
gorkaion@18649
   422
  END IF;
gorkaion@18649
   423
  RETURN;
gorkaion@18649
   424
END; --BODY
gorkaion@18649
   425
EXCEPTION
gorkaion@18649
   426
WHEN OTHERS THEN
gorkaion@18649
   427
  v_ResultStr:= '@ERROR=' || SQLERRM;
gorkaion@18649
   428
  DBMS_OUTPUT.PUT_LINE(v_ResultStr) ;
gorkaion@18649
   429
  IF (p_pinstance_id IS NOT NULL) THEN
gorkaion@18649
   430
    ROLLBACK;
unai@26090
   431
    AD_UPDATE_PINSTANCE(p_pinstance_id, NULL, 'N', 0, v_ResultStr, 'N') ;
gorkaion@18649
   432
  ELSE
gorkaion@18649
   433
    RAISE;
gorkaion@18649
   434
  END IF;
gorkaion@18649
   435
  RETURN;
gorkaion@18649
   436
END M_RESERVATION_POST
gorkaion@18649
   437
]]></body>
gorkaion@18649
   438
    </function>
gorkaion@18649
   439
  </database>