src-db/database/model/functions/M_RESERVATION_POST.xml
author Gorka Ion Damián <gorkaion.damian@openbravo.com>
Fri, 16 Nov 2012 09:14:11 +0100
changeset 18705 5966a12e0b3c
parent 18696 018782102b24
child 18745 7dfe05aa19c5
permissions -rw-r--r--
[Reservations]Add validations in Reservation Post.
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
gorkaion@18649
    28
* All portions are Copyright (C) 2012 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@18689
    44
  v_count           NUMBER;
gorkaion@18693
    45
  v_quantity        NUMBER;
gorkaion@18693
    46
  v_reservedqty     NUMBER;
gorkaion@18649
    47
gorkaion@18649
    48
TYPE RECORD IS REF CURSOR;
gorkaion@18649
    49
  Cur_Parameter RECORD;
gorkaion@18649
    50
gorkaion@18649
    51
BEGIN
gorkaion@18649
    52
  IF (p_PInstance_ID IS NOT NULL) THEN
gorkaion@18649
    53
    --  Update AD_PInstance
gorkaion@18649
    54
    DBMS_OUTPUT.PUT_LINE('Updating PInstance - Processing ' || p_pinstance_id) ;
gorkaion@18649
    55
    v_ResultStr:='PInstanceNotFound';
gorkaion@18649
    56
    AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'Y', NULL, NULL) ;
gorkaion@18649
    57
    --  Get Parameters
gorkaion@18649
    58
    v_ResultStr:='ReadingParameters';
gorkaion@18649
    59
    FOR Cur_Parameter IN (
gorkaion@18649
    60
        SELECT i.record_id, i.ad_user_id, p.parametername, p.p_string, p.p_number, p.p_date
gorkaion@18649
    61
        FROM ad_pinstance i
gorkaion@18649
    62
            LEFT JOIN ad_pinstance_para p ON i.ad_pinstance_id=p.ad_pinstance_id
gorkaion@18649
    63
        WHERE i.ad_pinstance_id=p_pinstance_id
gorkaion@18649
    64
        ORDER BY p.seqno
gorkaion@18649
    65
    ) LOOP
gorkaion@18649
    66
      IF (cur_parameter.parametername = 'RES_Action') THEN
gorkaion@18649
    67
        v_resaction := cur_parameter.p_string;
gorkaion@18649
    68
      END IF;
gorkaion@18649
    69
      v_reservation_id := cur_parameter.record_id;
gorkaion@18649
    70
      v_user_id := cur_parameter.ad_user_id;
gorkaion@18649
    71
    END LOOP; --  Get Parameter
gorkaion@18649
    72
    DBMS_OUTPUT.PUT_LINE('  v_Record_ID=' || v_reservation_id) ;
gorkaion@18649
    73
  ELSE
gorkaion@18649
    74
    v_reservation_id := p_reservation_id;
gorkaion@18649
    75
    v_resaction := p_resaction;
gorkaion@18649
    76
    v_user_id := p_user_id;
gorkaion@18649
    77
  END IF;
gorkaion@18649
    78
gorkaion@18649
    79
BEGIN
gorkaion@18696
    80
  SELECT res_status, c_orderline_id, quantity, reservedqty,
gorkaion@18696
    81
        m_product_id, c_uom_id
gorkaion@18696
    82
    INTO v_resstatus, v_orderline_id, v_quantity, v_reservedqty,
gorkaion@18696
    83
        v_product_id, v_uom_id
gorkaion@18649
    84
  FROM m_reservation
gorkaion@18649
    85
  WHERE m_reservation_id = v_reservation_id;
gorkaion@18649
    86
  
gorkaion@18649
    87
  IF (v_resaction = 'PR') THEN
gorkaion@18649
    88
  /*
gorkaion@18649
    89
    Reservation Complete Process
gorkaion@18649
    90
  */
gorkaion@18693
    91
    DECLARE
gorkaion@18693
    92
      v_sales_order_id        VARCHAR2(32);
gorkaion@18695
    93
      cur_not_available       RECORD;
gorkaion@18693
    94
      v_linecount             NUMBER;
gorkaion@18693
    95
      v_creservedcount        NUMBER;
gorkaion@18693
    96
      v_preservedcount        NUMBER;
gorkaion@18693
    97
    BEGIN
gorkaion@18693
    98
      IF (v_resstatus != 'DR') THEN
gorkaion@18693
    99
        RAISE_APPLICATION_ERROR(-20000, '@ActionNotSupported@');
gorkaion@18689
   100
      END IF;
gorkaion@18695
   101
      -- Check that stock is still available
gorkaion@18695
   102
      FOR cur_not_available IN (
gorkaion@18695
   103
        SELECT AD_COLUMN_IDENTIFIER('M_Locator', rs.m_locator_id, 'en_US') as locatorName,
gorkaion@18695
   104
               asi.description AS attributeName
gorkaion@18695
   105
        FROM m_reservation_stock rs
gorkaion@18695
   106
            JOIN m_attributesetinstance asi ON COALESCE(rs.m_attributesetinstance_id, '0') = asi.m_attributesetinstance_id
gorkaion@18695
   107
            LEFT JOIN m_storage_detail sd ON sd.m_product_id = v_product_id
gorkaion@18695
   108
                                             AND sd.c_uom_id = v_uom_id
gorkaion@18695
   109
                                             AND sd.m_product_uom_id IS NULL
gorkaion@18695
   110
                                             AND COALESCE(sd.m_attributesetinstance_id, '0') = COALESCE(rs.m_attributesetinstance_id, '0')
gorkaion@18695
   111
                                             AND sd.m_locator_id = rs.m_locator_id
gorkaion@18695
   112
            LEFT JOIN (
gorkaion@18695
   113
                    SELECT SUM(rs2.quantity - COALESCE(rs2.releasedqty,0)) AS reservedstock, rs2.m_locator_id, COALESCE(rs2.m_attributesetinstance_id,'0') AS m_attributesetinstance_id
gorkaion@18695
   114
                    FROM m_reservation_stock rs2
gorkaion@18695
   115
                      JOIN m_reservation r ON rs2.m_reservation_id = r.m_reservation_id
gorkaion@18695
   116
                    WHERE r.m_product_id = v_product_id
gorkaion@18695
   117
                      AND r.res_status NOT IN ('CL', 'DR')
gorkaion@18695
   118
                      AND r.c_uom_id = v_uom_id
gorkaion@18695
   119
                    GROUP BY rs2.m_locator_id, COALESCE(rs2.m_attributesetinstance_id,'0')
gorkaion@18695
   120
                  ) other ON rs.m_locator_id = other.m_locator_id
gorkaion@18695
   121
                             AND COALESCE(rs.m_attributesetinstance_id, '0') = COALESCE(other.m_attributesetinstance_id, '0')
gorkaion@18695
   122
        WHERE rs.quantity - COALESCE(rs.releasedqty, 0) > COALESCE(sd.qtyonhand, 0) - COALESCE(other.reservedstock, 0)
gorkaion@18695
   123
          AND rs.m_reservation_id = v_reservation_id
gorkaion@18695
   124
      ) LOOP
gorkaion@18695
   125
        RAISE_APPLICATION_ERROR(-20000, '@NotEnoughAvailableStock@ : ' || cur_not_available.locatorName || ' - ' || cur_not_available.attributeName);
gorkaion@18695
   126
      END LOOP;
gorkaion@18695
   127
      
gorkaion@18705
   128
      -- Check that prereserved quantity is equal all lower than ordered quantity
gorkaion@18705
   129
      FOR cur_not_available IN (
gorkaion@18705
   130
          SELECT AD_COLUMN_IDENTIFIER('C_Orderline', rs.c_orderline_id, 'en_US') as orderline
gorkaion@18705
   131
          FROM m_reservation_stock rs
gorkaion@18705
   132
              JOIN c_orderline ol ON rs.c_orderline_id = ol.c_orderline_id
gorkaion@18705
   133
              LEFT JOIN (
gorkaion@18705
   134
                  -- If reservation is closed consider only converted reservations as prereserve.
gorkaion@18705
   135
                  SELECT SUM(CASE r.res_status
gorkaion@18705
   136
                             WHEN 'CL' THEN CASE WHEN rs2.m_locator_id IS NULL THEN 0
gorkaion@18705
   137
                                            ELSE rs2.quantity END
gorkaion@18705
   138
                             ELSE rs2.quantity END) as qty, rs2.c_orderline_id
gorkaion@18705
   139
                  FROM m_reservation_stock rs2
gorkaion@18705
   140
                      JOIN m_reservation r ON rs2.m_reservation_id = r.m_reservation_id
gorkaion@18705
   141
                  WHERE rs2.c_orderline_id IS NOT NULL
gorkaion@18705
   142
                    AND r.res_status NOT IN ('DR')
gorkaion@18705
   143
                  GROUP BY rs2.c_orderline_id
gorkaion@18705
   144
                ) pre ON rs.c_orderline_id = pre.c_orderline_id
gorkaion@18705
   145
          WHERE rs.m_reservation_id = v_reservation_id
gorkaion@18705
   146
            AND rs.c_orderline_id IS NOT NULL
gorkaion@18705
   147
            AND ol.qtyordered < rs.quantity + COALESCE(pre.qty, 0)
gorkaion@18705
   148
      ) LOOP
gorkaion@18705
   149
        RAISE_APPLICATION_ERROR(-20000, '@MorePrereservedQtyThanOrdered@ '||cur_not_available.orderline);
gorkaion@18705
   150
      END LOOP;
gorkaion@18705
   151
      
gorkaion@18693
   152
      IF (v_orderline_id IS NOT NULL) THEN
gorkaion@18693
   153
        SELECT count(*) INTO v_count
gorkaion@18693
   154
        FROM m_reservation
gorkaion@18693
   155
        WHERE c_orderline_id = v_orderline_id
gorkaion@18693
   156
          AND m_reservation_id != v_reservation_id;
gorkaion@18693
   157
        IF (v_count > 0) THEN
gorkaion@18693
   158
          RAISE_APPLICATION_ERROR(-20000, '@SOLineWithMoreThanOneOpenReservation@');
gorkaion@18693
   159
        END IF;
gorkaion@18693
   160
  
gorkaion@18693
   161
        UPDATE c_orderline
gorkaion@18693
   162
        SET so_res_status = CASE WHEN v_quantity = v_reservedqty THEN 'CR'
gorkaion@18693
   163
                                 ELSE 'PR'
gorkaion@18693
   164
                            END
gorkaion@18693
   165
        WHERE c_orderline_id = v_orderline_id;
gorkaion@18693
   166
  
gorkaion@18693
   167
        SELECT c_order_id INTO v_sales_order_id
gorkaion@18693
   168
        FROM c_orderline
gorkaion@18693
   169
        WHERE c_orderline_id = v_orderline_id;
gorkaion@18693
   170
        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
   171
          INTO v_linecount, v_creservedcount, v_preservedcount
gorkaion@18693
   172
        FROM c_orderline
gorkaion@18693
   173
        WHERE c_order_id = v_sales_order_id;
gorkaion@18693
   174
  
gorkaion@18693
   175
        UPDATE c_order
gorkaion@18693
   176
        SET so_res_status = CASE WHEN v_linecount = v_creservedcount THEN 'CR'
gorkaion@18693
   177
                                 WHEN v_creservedcount + v_preservedcount > 0 THEN 'PR'
gorkaion@18693
   178
                                 ELSE 'NR'
gorkaion@18693
   179
                            END
gorkaion@18693
   180
        WHERE c_order_id = v_sales_order_id;
gorkaion@18693
   181
      END IF;
gorkaion@18693
   182
  
gorkaion@18693
   183
      v_newstatus := 'CO';
gorkaion@18693
   184
      v_newaction := 'HO';
gorkaion@18693
   185
      -- ADD RESERVED STOCK
gorkaion@18693
   186
      M_RESERVE_STOCK_AUTO(v_reservation_id, v_user_id, v_message);
gorkaion@18693
   187
    END;
gorkaion@18649
   188
gorkaion@18649
   189
  ELSIF (v_resaction = 'HO') THEN
gorkaion@18649
   190
  /*
gorkaion@18649
   191
    Reservation Hold Process
gorkaion@18649
   192
  */
gorkaion@18649
   193
    IF (v_resstatus != 'CO') THEN
gorkaion@18649
   194
      RAISE_APPLICATION_ERROR(-20000, '@ActionNotSupported@');
gorkaion@18649
   195
    END IF;
gorkaion@18649
   196
    v_newstatus := 'HO';
gorkaion@18649
   197
    v_newaction := 'UNHO';
gorkaion@18649
   198
  
gorkaion@18649
   199
  
gorkaion@18649
   200
  ELSIF (v_resaction = 'UNHO') THEN
gorkaion@18649
   201
  /*
gorkaion@18649
   202
    Reservation Un-Hold Process
gorkaion@18649
   203
  */
gorkaion@18649
   204
    IF (v_resstatus != 'HO') THEN
gorkaion@18649
   205
      RAISE_APPLICATION_ERROR(-20000, '@ActionNotSupported@');
gorkaion@18649
   206
    END IF;
gorkaion@18649
   207
    v_newstatus := 'CO';
gorkaion@18649
   208
    v_newaction := 'HO';
gorkaion@18649
   209
gorkaion@18649
   210
  ELSIF (v_resaction = 'RE') THEN
gorkaion@18649
   211
  /*
gorkaion@18649
   212
    Reservation Reactivate Process
gorkaion@18649
   213
  */
gorkaion@18693
   214
    DECLARE
gorkaion@18693
   215
      v_sales_order_id        VARCHAR2(32);
gorkaion@18693
   216
      v_reservedcount         NUMBER;
gorkaion@18693
   217
    BEGIN
gorkaion@18693
   218
gorkaion@18705
   219
      IF (v_resstatus NOT IN ('CO', 'CL')) THEN
gorkaion@18693
   220
        RAISE_APPLICATION_ERROR(-20000, '@ActionNotSupported@');
gorkaion@18693
   221
      END IF;
gorkaion@18693
   222
gorkaion@18693
   223
      UPDATE c_orderline
gorkaion@18693
   224
      SET so_res_status = 'NR'
gorkaion@18693
   225
      WHERE c_orderline_id = v_orderline_id;
gorkaion@18693
   226
gorkaion@18693
   227
      SELECT c_order_id INTO v_sales_order_id
gorkaion@18693
   228
      FROM c_orderline
gorkaion@18693
   229
      WHERE c_orderline_id = v_orderline_id;
gorkaion@18693
   230
      SELECT COUNT(*) INTO v_reservedcount
gorkaion@18693
   231
      FROM c_orderline
gorkaion@18693
   232
      WHERE c_order_id = v_sales_order_id
gorkaion@18693
   233
        AND so_res_status <> 'NR';
gorkaion@18693
   234
gorkaion@18693
   235
      UPDATE c_order
gorkaion@18693
   236
      SET so_res_status = CASE WHEN v_reservedcount > 0 THEN 'PR'
gorkaion@18693
   237
                               ELSE 'NR'
gorkaion@18693
   238
                          END
gorkaion@18693
   239
      WHERE c_order_id = v_sales_order_id;
gorkaion@18693
   240
gorkaion@18693
   241
      v_newstatus := 'DR';
gorkaion@18693
   242
      v_newaction := 'PR';
gorkaion@18693
   243
    END;
gorkaion@18649
   244
  
gorkaion@18649
   245
  ELSIF (v_resaction = 'CL') THEN
gorkaion@18649
   246
  /*
gorkaion@18649
   247
    Reservation Close Process
gorkaion@18649
   248
  */
gorkaion@18649
   249
    IF (v_resstatus != 'CO' AND v_resstatus != 'HO') THEN
gorkaion@18649
   250
      RAISE_APPLICATION_ERROR(-20000, '@ActionNotSupported@');
gorkaion@18649
   251
    END IF;
gorkaion@18649
   252
    v_newstatus := 'CL';
gorkaion@18705
   253
    v_newaction := 'RE';
gorkaion@18649
   254
gorkaion@18649
   255
  ELSE
gorkaion@18649
   256
    RAISE_APPLICATION_ERROR(-20000, '@UnsupportedResAction@');
gorkaion@18649
   257
  END IF;
gorkaion@18649
   258
gorkaion@18649
   259
  UPDATE m_reservation
gorkaion@18649
   260
  SET res_status = v_newstatus,
gorkaion@18649
   261
      res_process = v_newaction,
gorkaion@18649
   262
      updated = now(),
gorkaion@18649
   263
      updatedby = v_user_id
gorkaion@18649
   264
  WHERE m_reservation_id = v_reservation_id;
gorkaion@18649
   265
gorkaion@18649
   266
  IF (p_pinstance_id IS NOT NULL) THEN
gorkaion@18649
   267
    DBMS_OUTPUT.PUT_LINE('Updating PInstance - Finished ' || v_Message) ;
gorkaion@18649
   268
    AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'N', v_Result, v_Message) ;
gorkaion@18649
   269
    DBMS_OUTPUT.PUT_LINE('--<<M_Reservation_Post finished>> ' || v_Message) ;
gorkaion@18649
   270
  END IF;
gorkaion@18649
   271
  RETURN;
gorkaion@18649
   272
END; --BODY
gorkaion@18649
   273
EXCEPTION
gorkaion@18649
   274
WHEN OTHERS THEN
gorkaion@18649
   275
  v_ResultStr:= '@ERROR=' || SQLERRM;
gorkaion@18649
   276
  DBMS_OUTPUT.PUT_LINE(v_ResultStr) ;
gorkaion@18649
   277
  IF (p_pinstance_id IS NOT NULL) THEN
gorkaion@18649
   278
    ROLLBACK;
gorkaion@18649
   279
    AD_UPDATE_PINSTANCE(p_pinstance_id, NULL, 'N', 0, v_ResultStr) ;
gorkaion@18649
   280
  ELSE
gorkaion@18649
   281
    RAISE;
gorkaion@18649
   282
  END IF;
gorkaion@18649
   283
  RETURN;
gorkaion@18649
   284
END M_RESERVATION_POST
gorkaion@18649
   285
]]></body>
gorkaion@18649
   286
    </function>
gorkaion@18649
   287
  </database>