src-db/database/model/functions/GENERATESOFROMPROJECTORDER.xml
author Asier Lostalé <asier.lostale@openbravo.com>
Mon, 05 May 2008 06:59:24 +0000
changeset 799 fef2c5e2feb7
parent 756 ae11e4610537
child 1605 8a0fe0193bef
permissions -rw-r--r--
Merged cleanup branch (r3931) with trunk
carlos@0
     1
<?xml version="1.0"?>
adrian@94
     2
  <database name="FUNCTION GENERATESOFROMPROJECTORDER">
adrian@94
     3
    <function name="GENERATESOFROMPROJECTORDER" type="NULL">
antonio@735
     4
      <parameter name="p_pinstance_id" type="NUMERIC" mode="in">
antonio@735
     5
        <default/>
antonio@735
     6
      </parameter>
gorkaion@239
     7
      <body><![CDATA[/*************************************************************************
carlos@0
     8
* The contents of this file are subject to the Openbravo  Public  License
carlos@0
     9
* Version  1.0  (the  "License"),  being   the  Mozilla   Public  License
carlos@0
    10
* Version 1.1  with a permitted attribution clause; you may not  use this
carlos@0
    11
* file except in compliance with the License. You  may  obtain  a copy of
carlos@0
    12
* the License at http://www.openbravo.com/legal/license.html
carlos@0
    13
* Software distributed under the License  is  distributed  on  an "AS IS"
carlos@0
    14
* basis, WITHOUT WARRANTY OF ANY KIND, either express or implied. See the
carlos@0
    15
* License for the specific  language  governing  rights  and  limitations
carlos@0
    16
* under the License.
carlos@0
    17
* The Original Code is Openbravo ERP.
carlos@0
    18
* The Initial Developer of the Original Code is Openbravo SL
carlos@0
    19
* All portions are Copyright (C) 2001-2006 Openbravo SL
carlos@0
    20
* All Rights Reserved.
carlos@0
    21
* Contributor(s):  ______________________________________.
carlos@0
    22
************************************************************************/
carlos@0
    23
  v_ResultStr VARCHAR2(2000):='';
carlos@0
    24
  v_Message VARCHAR2(2000):='';
carlos@0
    25
  v_Result NUMBER:=1; -- 0=failure
carlos@0
    26
  v_Record_ID NUMBER;
carlos@0
    27
  v_AD_User_ID NUMBER;
carlos@0
    28
  v_M_PriceList_ID2 NUMBER;
carlos@0
    29
  TYPE RECORD IS REF CURSOR;
carlos@0
    30
    Cur_Parameter RECORD;
carlos@0
    31
    v_C_Order_ID NUMBER;
carlos@0
    32
    v_C_OrderLine_ID NUMBER;
carlos@0
    33
    v_C_DOCTYPE_ID NUMBER;
carlos@0
    34
    v_DocumentNo NUMBER;
carlos@0
    35
  BEGIN
carlos@0
    36
    --  Update AD_PInstance
carlos@0
    37
    DBMS_OUTPUT.PUT_LINE('Updating PInstance - Processing ' || p_PInstance_ID) ;
carlos@0
    38
    v_ResultStr:='PInstanceNotFound';
antonio@735
    39
    AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'Y', NULL, NULL) ;
carlos@0
    40
  BEGIN --BODY
carlos@0
    41
    -- Get PARAMETERS
carlos@0
    42
    v_ResultStr:='ReadingParameters';
carlos@0
    43
    FOR Cur_Parameter IN
carlos@0
    44
      (SELECT i.Record_ID, i.AD_User_ID, i.AD_Client_ID, i.AD_Org_ID, p.ParameterName,
carlos@0
    45
        p.P_String, p.P_Number, p.P_Date, p.P_Date_To
carlos@0
    46
      FROM AD_PINSTANCE i
carlos@0
    47
      LEFT JOIN AD_PINSTANCE_PARA p
carlos@0
    48
        ON i.AD_PInstance_ID=p.AD_PInstance_ID
carlos@0
    49
      WHERE i.AD_PInstance_ID=p_PInstance_ID
carlos@0
    50
      )
carlos@0
    51
    LOOP
carlos@0
    52
      v_Record_ID:=Cur_Parameter.Record_ID;
carlos@0
    53
      v_AD_User_ID:=Cur_Parameter.AD_User_ID;
carlos@0
    54
    END LOOP; -- Get Parameter
carlos@0
    55
    DBMS_OUTPUT.PUT_LINE('  Record_ID=' || v_Record_ID) ;
carlos@0
    56
    DECLARE
carlos@0
    57
      v_Size NUMBER;
carlos@0
    58
      v_UOM NUMBER;
carlos@0
    59
      v_PriceStd NUMBER;
carlos@0
    60
      v_PriceList NUMBER;
carlos@0
    61
      v_PriceLimit NUMBER;
carlos@0
    62
      v_C_UOM_ID NUMBER;
carlos@0
    63
      v_C_Currency_ID NUMBER;
carlos@0
    64
      v_M_PriceList_ID NUMBER;
carlos@0
    65
    TYPE RECORD IS REF CURSOR;
carlos@0
    66
      Cur_SO RECORD;
carlos@0
    67
      SOLINES RECORD;
carlos@0
    68
      FINISH_PROCESS BOOLEAN:=FALSE;
carlos@0
    69
    BEGIN
carlos@0
    70
      v_ResultStr:='StartLoop';
carlos@0
    71
      FOR Cur_SO IN
carlos@0
    72
        (SELECT * FROM C_PROJECT WHERE C_PROJECT_ID=v_Record_ID)
carlos@0
    73
      LOOP
carlos@0
    74
        -- Check that we have some restrictions
carlos@0
    75
        v_ResultStr:='CheckRestriction';
gorkaion@239
    76
        IF(Cur_SO.PROJECTSTATUS IS NULL OR Cur_SO.PROJECTSTATUS<>'OR') THEN
carlos@0
    77
          RAISE_APPLICATION_ERROR(-20000, '@Invalidprojectstatus@');
carlos@0
    78
        END IF;
carlos@0
    79
        IF(NOT FINISH_PROCESS) THEN
carlos@0
    80
          v_C_Order_ID:=Ad_Sequence_Nextno('C_Order') ;
carlos@0
    81
          v_ResultStr:='C_ORDER_ID - ' || v_C_Order_ID;
carlos@0
    82
          v_C_DOCTYPE_ID:=Ad_Get_Doctype(Cur_SO.AD_Client_ID, Cur_SO.AD_Org_ID, 'SOO', 'SO') ;
carlos@0
    83
          v_ResultStr:='C_DOCTYPE_ID - ' || v_C_DOCTYPE_ID;
carlos@0
    84
          Ad_Sequence_Doctype(v_C_DOCTYPE_ID, Cur_SO.AD_Client_ID, 'Y', v_DocumentNo) ;
carlos@0
    85
          IF(v_DocumentNo IS NULL) THEN
carlos@0
    86
            Ad_Sequence_Doc('DocumentNo_C_Order', Cur_SO.AD_Client_ID, 'Y', v_DocumentNo) ;
carlos@0
    87
          END IF;
carlos@0
    88
          SELECT M_PriceList_ID
carlos@0
    89
        INTO v_M_PriceList_ID2
carlos@0
    90
        FROM M_PRICELIST_VERSION
carlos@0
    91
        WHERE M_PriceList_Version_ID=Cur_SO.M_PRICELIST_VERSION_ID;
carlos@0
    92
        v_ResultStr:='DocumentNo - ' || v_DocumentNo || ' m_pricelist_id - ' || COALESCE(Cur_SO.m_pricelist_id, v_M_Pricelist_ID2);
carlos@0
    93
          INSERT
carlos@0
    94
          INTO C_ORDER
carlos@0
    95
            (
carlos@0
    96
              C_ORDER_ID, AD_CLIENT_ID, AD_ORG_ID, CREATEDBY,
carlos@0
    97
              UPDATEDBY, ISSOTRX, DOCUMENTNO, DOCSTATUS,
carlos@0
    98
              DOCACTION, C_DOCTYPE_ID, C_DOCTYPETARGET_ID, DATEORDERED,
carlos@0
    99
              DATEACCT, C_BPARTNER_ID, C_BPARTNER_LOCATION_ID, ISDISCOUNTPRINTED,
carlos@0
   100
              C_CURRENCY_ID, PAYMENTRULE, C_PAYMENTTERM_ID, INVOICERULE,
carlos@0
   101
              DELIVERYRULE, FREIGHTCOSTRULE, DELIVERYVIARULE, PRIORITYRULE,
carlos@0
   102
              TOTALLINES, GRANDTOTAL, M_WAREHOUSE_ID, M_PRICELIST_ID,
carlos@0
   103
              ISTAXINCLUDED, POSTED, PROCESSING, SALESREP_ID,
carlos@0
   104
              BILLTO_ID, C_CAMPAIGN_ID, C_PROJECT_ID, AD_USER_ID,
carlos@0
   105
              COPYFROM, DATEPROMISED
carlos@0
   106
            )
carlos@0
   107
            VALUES
carlos@0
   108
            (
carlos@0
   109
              v_C_Order_ID, Cur_SO.AD_CLIENT_ID, Cur_SO.AD_ORG_ID, v_AD_User_ID,
carlos@0
   110
              v_AD_User_ID, 'Y', v_DocumentNo, 'DR',
antonio@735
   111
               'CO', 0, v_C_DOCTYPE_ID, TRUNC(now(), 'DD'),
antonio@735
   112
              TRUNC(now(), 'DD'), Cur_SO.C_BPARTNER_ID, Cur_SO.C_BPARTNER_LOCATION_ID, 'N',
carlos@0
   113
              Cur_SO.C_CURRENCY_ID, COALESCE(Cur_SO.PAYMENTRULE, 'P'), Cur_SO.C_PAYMENTTERM_ID, 'D',
carlos@0
   114
               'A', 'I', 'D', '5',
carlos@0
   115
              0, 0, Cur_SO.M_WAREHOUSE_ID, COALESCE(Cur_SO.M_PRICELIST_ID, v_M_PriceList_ID2),
carlos@0
   116
               'N', 'N', 'N', Cur_SO.SALESREP_ID,
carlos@0
   117
              Cur_SO.BILLTO_ID, Cur_SO.C_CAMPAIGN_ID, Cur_SO.C_PROJECT_ID, Cur_SO.AD_User_ID,
antonio@735
   118
               'N', TRUNC(now(), 'DD')
carlos@0
   119
            )
carlos@0
   120
            ;
carlos@0
   121
          FOR SOLINES IN
carlos@0
   122
            (SELECT * FROM C_PROJECTLINE WHERE C_PROJECT_ID=v_Record_ID)
carlos@0
   123
          LOOP
carlos@0
   124
            IF(SOLINES.M_PRODUCT_ID IS NOT NULL AND Cur_SO.M_PRICELIST_VERSION_ID IS NOT NULL) THEN
carlos@0
   125
              v_ResultStr:='SOLINES1 - SO.M_PRICELIST_VERSION_ID - ' || Cur_SO.M_PRICELIST_VERSION_ID || ' - ' || SOLINES.M_PRODUCT_ID;
carlos@0
   126
              SELECT COUNT(p.C_UOM_ID)
carlos@0
   127
              INTO v_Size
carlos@0
   128
              FROM M_PRODUCT p,
carlos@0
   129
                M_PRODUCTPRICE pp,
carlos@0
   130
                M_PRICELIST_VERSION pv,
carlos@0
   131
                M_PRICELIST pl
carlos@0
   132
              WHERE p.M_Product_ID=pp.M_Product_ID
carlos@0
   133
                AND pp.M_PriceList_Version_ID=pv.M_PriceList_Version_ID
carlos@0
   134
                AND pv.M_PriceList_ID=pl.M_PriceList_ID
carlos@0
   135
                AND pv.IsActive='Y'
carlos@0
   136
                AND p.M_Product_ID=SOLINES.M_PRODUCT_ID
carlos@0
   137
                AND pv.M_PriceList_Version_ID=Cur_SO.M_PRICELIST_VERSION_ID;
gorkaion@239
   138
              IF(v_Size>0) THEN
carlos@0
   139
                SELECT Bom_Pricestd(p.M_Product_ID, pv.M_PriceList_Version_ID) AS PriceStd,
carlos@0
   140
                  Bom_Pricelist(p.M_Product_ID, pv.M_PriceList_Version_ID) AS PriceList,
carlos@0
   141
                  Bom_Pricelimit(p.M_Product_ID, pv.M_PriceList_Version_ID) AS PriceLimit,
carlos@0
   142
                  p.C_UOM_ID, pl.C_Currency_ID
carlos@0
   143
                INTO v_PriceStd, v_PriceList, v_PriceLimit, v_C_UOM_ID, v_C_Currency_ID
carlos@0
   144
                FROM M_PRODUCT p, M_PRODUCTPRICE pp,M_PRICELIST_VERSION pv,M_PRICELIST pl
carlos@0
   145
                WHERE p.M_Product_ID=pp.M_Product_ID
carlos@0
   146
                  AND pp.M_PriceList_Version_ID=pv.M_PriceList_Version_ID
carlos@0
   147
                  AND pv.M_PriceList_ID=pl.M_PriceList_ID
carlos@0
   148
                  AND pv.IsActive='Y'
carlos@0
   149
                  AND p.M_Product_ID=SOLINES.M_PRODUCT_ID
carlos@0
   150
                  AND pv.M_PriceList_Version_ID=Cur_SO.M_PRICELIST_VERSION_ID;
carlos@0
   151
              END IF;
carlos@0
   152
            END IF;
carlos@0
   153
            IF(SOLINES.M_PRODUCT_ID IS NOT NULL AND v_PriceStd IS NULL AND v_PriceList IS NULL AND v_PriceLimit IS NULL AND v_C_UOM_ID IS NULL AND v_C_Currency_ID IS NULL) THEN
carlos@0
   154
              v_ResultStr:='SOLINES - v_PriceStd - ' || v_PriceStd;
carlos@0
   155
              IF(Cur_SO.M_PRICELIST_ID IS NULL) THEN
carlos@0
   156
                SELECT M_PriceList_ID
carlos@0
   157
                INTO v_M_PriceList_ID
carlos@0
   158
                FROM M_PRICELIST pl,
carlos@0
   159
                  M_PRODUCT p
carlos@0
   160
                WHERE pl.AD_Client_ID=p.AD_Client_ID
carlos@0
   161
                  AND M_Product_ID=SOLINES.M_PRODUCT_ID
carlos@0
   162
                ORDER BY IsDefault DESC;
carlos@0
   163
              END IF;
carlos@0
   164
              v_ResultStr:='SOLINES2 - v_M_PriceList_ID - ' || v_M_PriceList_ID;
carlos@0
   165
              SELECT Bom_Pricestd(p.M_Product_ID, pv.M_PriceList_Version_ID) AS PriceStd,
carlos@0
   166
                Bom_Pricelist(p.M_Product_ID, pv.M_PriceList_Version_ID) AS PriceList,
carlos@0
   167
                Bom_Pricelimit(p.M_Product_ID, pv.M_PriceList_Version_ID) AS PriceLimit,
carlos@0
   168
                p.C_UOM_ID,pl.C_Currency_ID
carlos@0
   169
              INTO v_PriceStd,v_PriceList,v_PriceLimit,v_C_UOM_ID,v_C_Currency_ID
carlos@0
   170
              FROM M_PRODUCT p,M_PRODUCTPRICE pp,M_PRICELIST_VERSION pv,M_PRICELIST pl
carlos@0
   171
              WHERE p.M_Product_ID=pp.M_Product_ID
carlos@0
   172
                AND pp.M_PriceList_Version_ID=pv.M_PriceList_Version_ID
carlos@0
   173
                AND pv.M_PriceList_ID=pl.M_PriceList_ID
carlos@0
   174
                AND pv.IsActive='Y'
carlos@0
   175
                AND p.M_Product_ID=SOLINES.M_PRODUCT_ID
carlos@0
   176
                AND pv.M_PriceList_ID=COALESCE(Cur_SO.M_PRICELIST_ID, v_M_PriceList_ID)
carlos@0
   177
              ORDER BY pv.ValidFrom DESC;
carlos@0
   178
              v_ResultStr:='SOLINES - v_PriceStd - ' || v_PriceStd;
carlos@0
   179
            END IF;
carlos@0
   180
            IF(SOLINES.M_PRODUCT_ID IS NOT NULL AND v_PriceStd IS NULL AND v_PriceList IS NULL AND v_PriceLimit IS NULL AND v_C_UOM_ID IS NULL AND v_C_Currency_ID IS NULL) THEN
carlos@0
   181
              SELECT Bom_Pricestd(p.M_Product_ID, pv.M_PriceList_Version_ID) AS PriceStd,
carlos@0
   182
                Bom_Pricelist(p.M_Product_ID, pv.M_PriceList_Version_ID) AS PriceList,
carlos@0
   183
                Bom_Pricelimit(p.M_Product_ID, pv.M_PriceList_Version_ID) AS PriceLimit,
carlos@0
   184
                p.C_UOM_ID,pl.C_Currency_ID
carlos@0
   185
              INTO v_PriceStd,v_PriceList,v_PriceLimit,v_C_UOM_ID,v_C_Currency_ID
carlos@0
   186
              FROM M_PRODUCT p,M_PRODUCTPRICE pp,M_PRICELIST_VERSION pv,M_PRICELIST bpl,M_PRICELIST pl
carlos@0
   187
              WHERE p.M_Product_ID=pp.M_Product_ID
carlos@0
   188
                AND pp.M_PriceList_Version_ID=pv.M_PriceList_Version_ID
carlos@0
   189
                AND pv.M_PriceList_ID=bpl.M_PriceList_ID
carlos@0
   190
                AND bpl.M_PriceList_ID=pl.BasePriceList_ID
carlos@0
   191
                AND pv.IsActive='Y'
carlos@0
   192
                AND p.M_Product_ID=SOLINES.M_PRODUCT_ID
carlos@0
   193
                AND pl.M_PriceList_ID=COALESCE(Cur_SO.M_PRICELIST_ID, v_M_PriceList_ID)
carlos@0
   194
              ORDER BY pv.ValidFrom DESC;
carlos@0
   195
            END IF;
carlos@0
   196
            SELECT U.C_UOM_ID
carlos@0
   197
            INTO v_UOM
carlos@0
   198
            FROM C_UOM U,M_PRODUCT P
carlos@0
   199
            WHERE P.C_UOM_ID=U.C_UOM_ID
carlos@0
   200
              AND M_PRODUCT_ID=SOLINES.M_PRODUCT_ID;
carlos@0
   201
            v_C_OrderLine_ID:=Ad_Sequence_Nextno('C_OrderLine') ;
carlos@0
   202
            v_ResultStr:='C_OrderLine_ID - ' || v_C_OrderLine_ID;
carlos@0
   203
            INSERT
carlos@0
   204
            INTO C_ORDERLINE
carlos@0
   205
              (
carlos@0
   206
                DateOrdered, M_Warehouse_ID, QtyOrdered, QtyDelivered,
asier@799
   207
                QtyReserved, M_Shipper_ID, QtyInvoiced,
carlos@0
   208
                C_Currency_ID, PriceList, DatePromised, DateDelivered,
carlos@0
   209
                DateInvoiced, Created, IsActive, Line,
carlos@0
   210
                C_OrderLine_ID, AD_Client_ID, C_Order_ID, Description,
carlos@0
   211
                M_Product_ID, C_UOM_ID, DirectShip, CreatedBy,
carlos@0
   212
                UpdatedBy, FreightAmt, C_Charge_ID, ChargeAmt,
carlos@0
   213
                Updated, AD_Org_ID, S_ResourceAssignment_ID, C_BPartner_ID,
asier@799
   214
                PriceActual, C_Tax_ID, C_BPartner_Location_ID,
carlos@0
   215
                Discount, PriceLimit, Ref_OrderLine_ID, LineNetAmt,
carlos@0
   216
                M_AttributeSetInstance_ID, IsDescription, PriceStd
carlos@0
   217
              )
carlos@0
   218
              VALUES
carlos@0
   219
              (
antonio@735
   220
                TRUNC(now(), 'DD'), Cur_SO.M_WAREHOUSE_ID, SOLINES.InvoicedQty, 0,
asier@799
   221
                0, NULL, 0,
antonio@735
   222
                Cur_SO.C_CURRENCY_ID, v_PriceList, TRUNC(now(), 'DD'), NULL,
antonio@735
   223
                NULL, now(), 'Y', SOLINES.LINE,
carlos@0
   224
                v_C_OrderLine_ID, Cur_SO.AD_CLIENT_ID, v_C_Order_ID, SOLINES.DESCRIPTION,
carlos@0
   225
                SOLINES.M_PRODUCT_ID, v_UOM, 'N', v_AD_User_ID,
carlos@0
   226
                v_AD_User_ID, 0, NULL, 0,
antonio@735
   227
                now(), Cur_SO.AD_ORG_ID, NULL, Cur_SO.C_BPARTNER_ID,
antonio@735
   228
                M_Get_Offers_Price(now(), Cur_SO.C_BPARTNER_ID, SOLINES.M_PRODUCT_ID, v_PriceStd, SOLINES.InvoicedQty,  v_M_PriceList_ID),
asier@799
   229
    C_Gettax(SOLINES.M_PRODUCT_ID, TRUNC(now(), 'DD'), Cur_SO.AD_ORG_ID, Cur_SO.M_WAREHOUSE_ID, Cur_SO.C_BPARTNER_LOCATION_ID, Cur_SO.C_BPARTNER_LOCATION_ID, Cur_SO.C_PROJECT_ID, 'Y'), Cur_SO.C_BPARTNER_LOCATION_ID,
antonio@735
   230
                (v_PriceList-v_PriceStd) *100/v_PriceList, v_PriceLimit, NULL, (M_Get_Offers_Price(now(), Cur_SO.C_BPARTNER_ID, SOLINES.M_PRODUCT_ID, v_PriceStd, SOLINES.InvoicedQty,  v_M_PriceList_ID) * SOLINES.InvoicedQty),
carlos@0
   231
                NULL, 'N', v_PriceStd
carlos@0
   232
              )
carlos@0
   233
              ;
carlos@0
   234
          END LOOP;
carlos@0
   235
          IF v_Message IS NOT NULL THEN
carlos@0
   236
            v_Message:=v_Message || ', ';
carlos@0
   237
          END IF;
carlos@0
   238
          v_Message:=v_Message || v_DocumentNo;
carlos@0
   239
        END IF;--FINISH_PROCESS
carlos@0
   240
      END LOOP;
carlos@0
   241
      v_Message:='@DocumentNo@: ' || v_Message;
carlos@0
   242
    END;
gorkaion@239
   243
    --<<FINISH_PROCESS>>
carlos@0
   244
    --  Update AD_PInstance
carlos@0
   245
    DBMS_OUTPUT.PUT_LINE('Updating PInstance - Finished ' || v_Message) ;
antonio@735
   246
    AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'N', v_Result, v_Message) ;
carlos@0
   247
    RETURN;
carlos@0
   248
  END; --BODY
carlos@0
   249
EXCEPTION
carlos@0
   250
WHEN OTHERS THEN
carlos@0
   251
  v_ResultStr:= '@ERROR=' || SQLERRM;
carlos@0
   252
  DBMS_OUTPUT.PUT_LINE(v_ResultStr) ;
carlos@0
   253
  ROLLBACK;
antonio@735
   254
  AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'N', 0, v_ResultStr) ;
carlos@0
   255
  RETURN;
antonio@735
   256
END GENERATESOFROMPROJECTORDER
gorkaion@239
   257
]]></body>
adrian@94
   258
    </function>
adrian@94
   259
  </database>