src-db/database/model/functions/M_INOUT_CREATEINVOICE.xml
author Juan Pablo Aroztegi <juanpablo.aroztegi@openbravo.com>
Wed, 03 Sep 2008 17:55:37 +0000
changeset 1605 8a0fe0193bef
parent 1259 aa36b7150211
child 2857 a044fb50efaf
permissions -rw-r--r--
Merge r2.5x intro trunk
carlos@0
     1
<?xml version="1.0"?>
adrian@94
     2
  <database name="FUNCTION M_INOUT_CREATEINVOICE">
adrian@94
     3
    <function name="M_INOUT_CREATEINVOICE" type="NULL">
juanpablo@1605
     4
      <parameter name="p_pinstance_id" type="VARCHAR" mode="in">
antonio@735
     5
        <default/>
antonio@735
     6
      </parameter>
gorkaion@239
     7
      <body><![CDATA[/*************************************************************************
juanpablo@771
     8
  * The contents of this file are subject to the Compiere Public
juanpablo@771
     9
  * License 1.1 ("License"); You may not use this file except in
juanpablo@771
    10
  * compliance with the License. You may obtain a copy of the License in
juanpablo@771
    11
  * the legal folder of your Openbravo installation.
carlos@0
    12
  * Software distributed under the License is distributed on an
carlos@0
    13
  * "AS IS" basis, WITHOUT WARRANTY OF ANY KIND, either express or
carlos@0
    14
  * implied. See the License for the specific language governing rights
carlos@0
    15
  * and limitations under the License.
juanpablo@778
    16
  * The Original Code is  Compiere  ERP &  Business Solution
juanpablo@771
    17
  * The Initial Developer of the Original Code is Jorg Janke and ComPiere, Inc.
carlos@0
    18
  * Portions created by Jorg Janke are Copyright (C) 1999-2001 Jorg Janke,
carlos@0
    19
  * parts created by ComPiere are Copyright (C) ComPiere, Inc.;
carlos@0
    20
  * All Rights Reserved.
carlos@0
    21
  * Contributor(s): Openbravo SL
juanpablo@785
    22
  * Contributions are Copyright (C) 2001-2008 Openbravo, S.L.
juanpablo@771
    23
  *
juanpablo@771
    24
  * Specifically, this derivative work is based upon the following Compiere
juanpablo@771
    25
  * file and version.
carlos@0
    26
  *************************************************************************
carlos@0
    27
  * $Id: M_InOut_CreateInvoice.sql,v 1.7 2003/07/22 05:41:27 jjanke Exp $
carlos@0
    28
  ***
carlos@0
    29
  * Title: Create Invoice from Shipment
carlos@0
    30
  * Description:
carlos@0
    31
  ************************************************************************/
carlos@0
    32
  -- Logistice
carlos@0
    33
  v_ResultStr VARCHAR2(2000):='';
carlos@0
    34
  v_Message VARCHAR2(2000):='';
juanpablo@1605
    35
  v_Record_ID VARCHAR2(32);
carlos@0
    36
  -- Parameter
carlos@0
    37
  TYPE RECORD IS REF CURSOR;
carlos@0
    38
    Cur_Parameter RECORD;
carlos@0
    39
    -- Parameter Variables
juanpablo@1605
    40
    v_M_PriceList_Version_ID VARCHAR2(32);
carlos@0
    41
  BEGIN
carlos@0
    42
    --  Update AD_PInstance
carlos@0
    43
    DBMS_OUTPUT.PUT_LINE('Updating PInstance - Processing ' || p_PInstance_ID) ;
carlos@0
    44
    v_ResultStr:='PInstanceNotFound';
antonio@735
    45
    AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'Y', NULL, NULL) ;
carlos@0
    46
  BEGIN --BODY
carlos@0
    47
    -- Get Parameters
carlos@0
    48
    v_ResultStr:='ReadingParameters';
carlos@0
    49
    FOR Cur_Parameter IN
carlos@0
    50
      (SELECT i.Record_ID,
carlos@0
    51
        p.ParameterName,
carlos@0
    52
        p.P_String,
carlos@0
    53
        p.P_Number,
carlos@0
    54
        p.P_Date
carlos@0
    55
      FROM AD_PINSTANCE i
carlos@0
    56
      LEFT JOIN AD_PINSTANCE_PARA p
carlos@0
    57
        ON i.AD_PInstance_ID=p.AD_PInstance_ID
carlos@0
    58
      WHERE i.AD_PInstance_ID=p_PInstance_ID
carlos@0
    59
      ORDER BY p.SeqNo
carlos@0
    60
      )
carlos@0
    61
    LOOP
carlos@0
    62
      v_Record_ID:=Cur_Parameter.Record_ID;
carlos@0
    63
      IF(Cur_Parameter.ParameterName='M_PriceList_Version_ID') THEN
juanpablo@1605
    64
        v_M_PriceList_Version_ID:=Cur_Parameter.P_String;
carlos@0
    65
        DBMS_OUTPUT.PUT_LINE('  M_PriceList_Version_ID=' || v_M_PriceList_Version_ID) ;
carlos@0
    66
      ELSE
carlos@0
    67
        DBMS_OUTPUT.PUT_LINE('*** Unknown Parameter=' || Cur_Parameter.ParameterName) ;
carlos@0
    68
      END IF;
carlos@0
    69
    END LOOP; -- Get Parameter
carlos@0
    70
    DBMS_OUTPUT.PUT_LINE('  Record_ID=' || v_Record_ID) ;
carlos@0
    71
    DECLARE
carlos@0
    72
      Cur_Shipment RECORD;
carlos@0
    73
      Cur_ShipmentLines RECORD;
carlos@0
    74
      --
juanpablo@1605
    75
      v_Invoice_ID VARCHAR2(32) ;
juanpablo@1605
    76
      v_NextNo VARCHAR2(32) ;
juanpablo@1605
    77
      v_DocType_ID VARCHAR2(32) ;
carlos@0
    78
      v_InvoiceNo NUMBER(10) ;
carlos@0
    79
      v_DocumentNo C_INVOICE.DocumentNo%TYPE;
carlos@0
    80
      v_IsDiscountPrinted CHAR(1) ;
carlos@0
    81
      v_PaymentRule CHAR(1) ;
juanpablo@1605
    82
      v_C_PaymentTerm_ID VARCHAR2(32) ;
juanpablo@1605
    83
      v_C_Currency_ID VARCHAR2(32) ;
juanpablo@1605
    84
      v_M_PriceList_ID VARCHAR2(32) ;
carlos@0
    85
      --
juanpablo@1605
    86
      v_C_UOM_ID VARCHAR2(32) ;
juanpablo@1605
    87
      v_C_Tax_ID VARCHAR2(32) ;
carlos@0
    88
      v_PriceList NUMBER;
carlos@0
    89
      v_PriceActual NUMBER;
carlos@0
    90
      v_PriceLimit NUMBER;
carlos@0
    91
      --
carlos@0
    92
      v_LineNetAmt NUMBER;
carlos@0
    93
      v_TotalNet NUMBER;
juanpablo@1605
    94
      -- v_Offer_ID       varchar2(32);
carlos@0
    95
    BEGIN
carlos@0
    96
      FOR CUR_Shipment IN
carlos@0
    97
        (SELECT *  FROM M_INOUT  WHERE M_InOut_ID=v_Record_ID)
carlos@0
    98
      LOOP -- Just to have all variables
carlos@0
    99
        v_DocumentNo:=NULL;
carlos@0
   100
        DECLARE
carlos@0
   101
          Cur_CInvoiceCInvLine RECORD;
carlos@0
   102
        BEGIN
carlos@0
   103
          v_ResultStr:='Check Invoice exists';
carlos@0
   104
          FOR Cur_CInvoiceCInvLine IN
carlos@0
   105
            (SELECT i.DocumentNo,
carlos@0
   106
              i.C_Invoice_ID
carlos@0
   107
            FROM C_INVOICE i,
carlos@0
   108
              C_INVOICELINE il,
carlos@0
   109
              M_INOUTLINE iol
carlos@0
   110
            WHERE i.C_Invoice_ID=il.C_Invoice_ID
carlos@0
   111
              AND il.M_InOutLine_ID=iol.M_InOutLine_ID
carlos@0
   112
              AND iol.M_InOut_ID=CUR_Shipment.M_InOut_ID
carlos@0
   113
            )
carlos@0
   114
          LOOP
carlos@0
   115
            v_DocumentNo:=Cur_CInvoiceCInvLine.DocumentNo;
carlos@0
   116
            v_Invoice_ID:=Cur_CInvoiceCInvLine.C_Invoice_ID;
carlos@0
   117
            EXIT;
carlos@0
   118
          END LOOP;
carlos@0
   119
        EXCEPTION
carlos@0
   120
        WHEN OTHERS THEN
carlos@0
   121
          NULL;
carlos@0
   122
        END;
carlos@0
   123
        -- We have an Invoice
carlos@0
   124
        IF(v_DocumentNo IS NOT NULL) THEN
carlos@0
   125
          v_Message:='@ShipmentCreateDocAlreadyExists@ = '  || v_DocumentNo || ' (' || v_Invoice_ID || ')';
carlos@0
   126
          -- Shipment must be complete
carlos@0
   127
        ELSIF(CUR_Shipment.DocStatus NOT IN('CO', 'CL')) THEN
carlos@0
   128
          v_Message:='@ShipmentCreateDocNotCompleted@';
antonio@966
   129
          RAISE_APPLICATION_ERROR(-20000, v_Message);
carlos@0
   130
          -- Create Invoice from Shipment
carlos@0
   131
        ELSE
carlos@0
   132
          v_ResultStr:='GetBPartnerInfo'; -- P=OnCredit
carlos@0
   133
          SELECT IsDiscountPrinted,(
carlos@0
   134
            CASE WHEN PaymentRulePO IS NULL THEN 'P' ELSE PaymentRulePO
carlos@0
   135
            END
carlos@0
   136
            ),
carlos@0
   137
            PO_PaymentTerm_ID
carlos@0
   138
          INTO v_IsDiscountPrinted,
carlos@0
   139
            v_PaymentRule,
carlos@0
   140
            v_C_PaymentTerm_ID
carlos@0
   141
          FROM C_BPARTNER
carlos@0
   142
          WHERE C_BPartner_ID=CUR_Shipment.C_BPartner_ID;
carlos@0
   143
          -- Get PaymentTerms
carlos@0
   144
          IF(v_C_PaymentTerm_ID IS NULL) THEN
carlos@0
   145
            v_ResultStr:='GetPaymentTerm'; -- let it fail if no unique record
carlos@0
   146
            v_Message:='@NoPaymentTerm@';
carlos@0
   147
            DECLARE
carlos@0
   148
              Cur_CPayTerm RECORD;
carlos@0
   149
            BEGIN
carlos@0
   150
              FOR Cur_CPayTerm IN
carlos@0
   151
                (SELECT C_PaymentTerm_ID
carlos@0
   152
                FROM C_PAYMENTTERM
carlos@0
   153
                WHERE AD_Client_ID=CUR_Shipment.AD_Client_ID
carlos@0
   154
                ORDER BY IsDefault DESC,
carlos@0
   155
                  NetDays ASC
carlos@0
   156
                )
carlos@0
   157
              LOOP
carlos@0
   158
                v_C_PaymentTerm_ID:=Cur_CPayTerm.C_PaymentTerm_ID;
carlos@0
   159
                EXIT;
carlos@0
   160
              END LOOP;
carlos@0
   161
            END;
carlos@0
   162
          END IF;
carlos@0
   163
          --
carlos@0
   164
          IF(CUR_Shipment.C_Order_ID IS NOT NULL) THEN
carlos@0
   165
            v_ResultStr:='GetCurrencyInfo-Order';
carlos@0
   166
            SELECT C_Currency_ID,
carlos@0
   167
              M_PriceList_ID
carlos@0
   168
            INTO v_C_Currency_ID,
carlos@0
   169
              v_M_PriceList_ID
carlos@0
   170
            FROM C_ORDER
carlos@0
   171
            WHERE C_Order_ID=CUR_Shipment.C_Order_ID;
carlos@0
   172
          ELSE
carlos@0
   173
            v_ResultStr:='GetCurrencyInfo-PL';
carlos@0
   174
            SELECT pl.C_Currency_ID,
carlos@0
   175
              pl.M_PriceList_ID
carlos@0
   176
            INTO v_C_Currency_ID,
carlos@0
   177
              v_M_PriceList_ID
carlos@0
   178
            FROM M_PRICELIST pl,
carlos@0
   179
              M_PRICELIST_VERSION plv
carlos@0
   180
            WHERE pl.M_PriceList_ID=plv.M_PriceList_ID
carlos@0
   181
              AND M_PriceList_Version_ID=v_M_PriceList_Version_ID;
carlos@0
   182
          END IF;
carlos@0
   183
          --
carlos@0
   184
          v_ResultStr:='GetDocTypeInfo';
carlos@0
   185
          v_DocType_ID:=Ad_Get_Doctype(CUR_Shipment.AD_Client_ID, CUR_Shipment.AD_Org_ID, 'API') ;
carlos@0
   186
          --
carlos@0
   187
          Ad_Sequence_Next('C_Invoice', CUR_Shipment.AD_Client_ID, v_Invoice_ID) ;
carlos@0
   188
          Ad_Sequence_Doctype(v_DocType_ID, CUR_Shipment.AD_Client_ID, 'Y', v_DocumentNo) ;
carlos@0
   189
          IF(v_DocumentNo IS NULL) THEN
carlos@0
   190
            Ad_Sequence_Doc('DocumentNo_C_Invoice', CUR_Shipment.AD_Client_ID, 'Y', v_DocumentNo) ;
carlos@0
   191
          END IF;
carlos@0
   192
          IF(v_DocumentNo IS NULL) THEN
carlos@0
   193
            v_DocumentNo:=CUR_Shipment.DocumentNo; --  use the Receipt
carlos@0
   194
          END IF;
carlos@0
   195
          --
carlos@0
   196
          DBMS_OUTPUT.PUT_LINE('  Invoice_ID=' || v_Invoice_ID || ' DocumentNo=' || v_DocumentNo) ;
carlos@0
   197
          v_ResultStr:='InsertInvoice ' || v_Invoice_ID;
carlos@0
   198
          v_Message:='@DocumentNo@ = ' || v_DocumentNo;
carlos@0
   199
          INSERT
carlos@0
   200
          INTO C_INVOICE
carlos@0
   201
            (
carlos@0
   202
              C_Invoice_ID, C_Order_ID, AD_Client_ID, AD_Org_ID,
carlos@0
   203
              IsActive, Created, CreatedBy, Updated,
carlos@0
   204
              UpdatedBy, IsSOTrx, DocumentNo, DocStatus,
carlos@0
   205
              DocAction, Processing, Processed, C_DocType_ID,
carlos@1259
   206
              C_DocTypeTarget_ID, Description, SalesRep_ID, 
carlos@1259
   207
              DateInvoiced, DatePrinted, IsPrinted, TaxDate,
carlos@0
   208
              DateAcct, C_PaymentTerm_ID, C_BPartner_ID, C_BPartner_Location_ID,
carlos@0
   209
              AD_User_ID, POReference, DateOrdered, IsDiscountPrinted,
carlos@0
   210
              C_Currency_ID, PaymentRule, C_Charge_ID, ChargeAmt,
carlos@0
   211
              TotalLines, GrandTotal, M_PriceList_ID, C_Campaign_ID,
carlos@0
   212
              C_Project_ID, C_Activity_ID, AD_OrgTrx_ID, User1_ID,
carlos@0
   213
              User2_ID
carlos@0
   214
            )
carlos@0
   215
            VALUES
carlos@0
   216
            (
carlos@0
   217
              v_Invoice_ID, CUR_Shipment.C_Order_ID, CUR_Shipment.AD_Client_ID, CUR_Shipment.AD_Org_ID,
juanpablo@1605
   218
               'Y', now(), '0', now(),
juanpablo@1605
   219
              '0', 'N', v_DocumentNo, 'DR',
carlos@0
   220
               'CO', 'N', 'N', v_DocType_ID,
carlos@1259
   221
              v_DocType_ID, CUR_Shipment.Description, NULL, 
carlos@1259
   222
              now(), NULL, 'N', now(),
antonio@735
   223
              now(), v_C_PaymentTerm_ID, CUR_Shipment.C_BPartner_ID, CUR_Shipment.C_BPartner_Location_ID,
carlos@0
   224
              CUR_Shipment.AD_User_ID, NULL, CUR_Shipment.DateOrdered, v_IsDiscountPrinted,
carlos@0
   225
              v_C_Currency_ID, v_PaymentRule, NULL, 0,
carlos@0
   226
              0, 0, v_M_PriceList_ID, CUR_Shipment.C_Campaign_ID,
carlos@0
   227
              CUR_Shipment.C_Project_ID, CUR_Shipment.C_Activity_ID, CUR_Shipment.AD_OrgTrx_ID, CUR_Shipment.User1_ID,
carlos@0
   228
              CUR_Shipment.User2_ID
carlos@0
   229
            )
carlos@0
   230
            ;
carlos@0
   231
          -- Lines
carlos@0
   232
          v_TotalNet:=0;
carlos@0
   233
          FOR CUR_ShipmentLines IN
carlos@0
   234
            (SELECT *  FROM M_INOUTLINE  WHERE M_InOut_ID=v_Record_ID)
carlos@0
   235
          LOOP
carlos@0
   236
            -- Get Price
carlos@0
   237
            IF(CUR_ShipmentLines.C_OrderLine_ID IS NOT NULL) THEN
carlos@0
   238
              v_ResultStr:='GettingPrice-Order';
carlos@0
   239
              SELECT COALESCE(MAX(PriceList), 0),
carlos@0
   240
                COALESCE(MAX(PriceActual), 0),
carlos@0
   241
                COALESCE(MAX(PriceLimit), 0)
carlos@0
   242
              INTO v_PriceList,
carlos@0
   243
                v_PriceActual,
carlos@0
   244
                v_PriceLimit
carlos@0
   245
              FROM C_ORDERLINE
carlos@0
   246
              WHERE C_OrderLine_ID=CUR_ShipmentLines.C_OrderLine_ID;
carlos@0
   247
            ELSE
carlos@0
   248
              v_ResultStr:='GettingPrice-PList';
carlos@0
   249
              SELECT COALESCE(MAX(PriceList), 0),
carlos@0
   250
                COALESCE(MAX(PriceStd), 0),
carlos@0
   251
                COALESCE(MAX(PriceLimit), 0)
carlos@0
   252
              INTO v_PriceList,
carlos@0
   253
                v_PriceActual,
carlos@0
   254
                v_PriceLimit
carlos@0
   255
              FROM M_PRODUCTPRICE
carlos@0
   256
              WHERE M_Product_ID=CUR_ShipmentLines.M_Product_ID
carlos@0
   257
                AND M_PriceList_Version_ID=v_M_PriceList_Version_ID;
carlos@0
   258
            END IF;
carlos@0
   259
            -- Get UOM + Tax -- VERY simplified, but should work in most cases
carlos@0
   260
            v_ResultStr:='NoUOM+Tax';
carlos@0
   261
            SELECT C_UOM_ID
carlos@0
   262
            INTO v_C_UOM_ID
carlos@0
   263
            FROM M_PRODUCT
carlos@0
   264
            WHERE M_Product_ID=CUR_ShipmentLines.M_Product_ID;
carlos@0
   265
            v_C_Tax_ID:=C_Gettax(CUR_ShipmentLines.M_Product_ID, CUR_Shipment.MovementDate, CUR_Shipment.AD_Org_ID, CUR_Shipment.M_Warehouse_ID, CUR_Shipment.C_BPartner_Location_ID, CUR_Shipment.C_BPartner_Location_ID, CUR_Shipment.C_Project_ID, 'N') ;
carlos@0
   266
            -- v_UOM_ID, v_Tax_ID
carlos@0
   267
            v_ResultStr:='InsertInvoiceLine';
carlos@0
   268
            Ad_Sequence_Next('C_InvoiceLine', CUR_Shipment.C_Order_ID, v_NextNo) ;
antonio@735
   269
            v_LineNetAmt:=ROUND(M_Get_Offers_Price(now(), CUR_Shipment.C_BPartner_ID, CUR_ShipmentLines.M_Product_ID, v_PriceActual, CUR_ShipmentLines.MovementQty, v_M_PriceList_ID) *CUR_ShipmentLines.MovementQty, 2) ;
carlos@0
   270
            INSERT
carlos@0
   271
            INTO C_INVOICELINE
carlos@0
   272
              (
carlos@0
   273
                C_InvoiceLine_ID, AD_Client_ID, AD_Org_ID, IsActive,
carlos@0
   274
                Created, CreatedBy, Updated, UpdatedBy,
carlos@0
   275
                C_Invoice_ID, C_OrderLine_ID, M_InOutLine_ID, Line,
carlos@0
   276
                Description, M_Product_ID, QtyInvoiced, PriceList,
carlos@0
   277
                PriceActual, PriceLimit, LineNetAmt, C_Charge_ID,
carlos@0
   278
                ChargeAmt, C_UOM_ID,
carlos@0
   279
                C_Tax_ID,  --MODIFIED BY F.IRIAZABAL
carlos@0
   280
                QuantityOrder, M_Product_Uom_ID, PriceStd
carlos@0
   281
              )
carlos@0
   282
              VALUES
carlos@0
   283
              (
carlos@0
   284
                v_NextNo, CUR_Shipment.AD_Client_ID, CUR_ShipmentLines.AD_Org_ID, 'Y',
juanpablo@1605
   285
                now(), '100', now(), '0', -- LineTrigger reqirement
carlos@0
   286
                v_Invoice_ID, CUR_ShipmentLines.C_OrderLine_ID, CUR_ShipmentLines.M_InOutLine_ID, CUR_ShipmentLines.Line,
carlos@0
   287
                CUR_ShipmentLines.Description, CUR_ShipmentLines.M_Product_ID, CUR_ShipmentLines.MovementQty, v_PriceList,
antonio@735
   288
                M_Get_Offers_Price(now(), CUR_Shipment.C_BPartner_ID, CUR_ShipmentLines.M_Product_ID, v_PriceActual, CUR_ShipmentLines.MovementQty, v_M_PriceList_ID), v_PriceLimit, v_LineNetAmt, NULL,
carlos@0
   289
                0, v_C_UOM_ID,
carlos@0
   290
                v_C_Tax_ID,  --MODIFIED BY F.IRIAZABAL
carlos@0
   291
                CUR_ShipmentLines.QuantityOrder, CUR_ShipmentLines.M_Product_Uom_ID, v_PriceActual
carlos@0
   292
              )
carlos@0
   293
              ;
carlos@0
   294
            v_TotalNet:=v_TotalNet + v_LineNetAmt;
carlos@0
   295
          END LOOP; -- ShipLines
carlos@0
   296
        END IF;
carlos@0
   297
      END LOOP; -- All Shipments
carlos@0
   298
    END;
gorkaion@239
   299
    --<<FINISH_PROCESS>>
carlos@0
   300
    --  Update AD_PInstance
carlos@0
   301
    DBMS_OUTPUT.PUT_LINE('Updating PInstance - Finished ' || v_Message) ;
antonio@735
   302
    AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'N', 1, v_Message) ;
carlos@0
   303
    RETURN;
carlos@0
   304
  END; --BODY
carlos@0
   305
EXCEPTION
carlos@0
   306
WHEN OTHERS THEN
carlos@0
   307
  v_ResultStr:= '@ERROR=' || SQLERRM;
carlos@0
   308
  DBMS_OUTPUT.PUT_LINE(v_ResultStr) ;
carlos@0
   309
  ROLLBACK;
antonio@735
   310
  AD_UPDATE_PINSTANCE(p_PInstance_ID, NULL, 'N', 0, v_ResultStr) ;
carlos@0
   311
  RETURN;
antonio@735
   312
END M_INOUT_CREATEINVOICE
gorkaion@239
   313
]]></body>
adrian@94
   314
    </function>
adrian@94
   315
  </database>