modules/org.openbravo.advpaymentmngt/src-db/database/model/functions/APRM_GEN_PAYMENTSCHEDULE_INV.xml
changeset 9076 c4f1a5c7d7c2
child 9908 8865c74fc6b9
equal deleted inserted replaced
9075:b3ea04de2722 9076:c4f1a5c7d7c2
       
     1 <?xml version="1.0"?>
       
     2   <database name="FUNCTION APRM_GEN_PAYMENTSCHEDULE_INV">
       
     3     <function name="APRM_GEN_PAYMENTSCHEDULE_INV" type="NULL">
       
     4       <parameter name="p_ep_instance" type="VARCHAR" mode="in">
       
     5         <default/>
       
     6       </parameter>
       
     7       <body><![CDATA[/*************************************************************************
       
     8 * The contents of this file are subject to the Openbravo  Public  License
       
     9 * Version  1.0  (the  "License"),  being   the  Mozilla   Public  License
       
    10 * Version 1.1  with a permitted attribution clause; you may not  use this
       
    11 * file except in compliance with the License. You  may  obtain  a copy of
       
    12 * the License at http://www.openbravo.com/legal/license.html
       
    13 * Software distributed under the License  is  distributed  on  an "AS IS"
       
    14 * basis, WITHOUT WARRANTY OF ANY KIND, either express or implied. See the
       
    15 * License for the specific  language  governing  rights  and  limitations
       
    16 * under the License.
       
    17 * The Original Code is Openbravo ERP.
       
    18 * The Initial Developer of the Original Code is Openbravo SLU
       
    19 * All portions are Copyright (C) 2010 Openbravo SLU
       
    20 * All Rights Reserved.
       
    21 * Contributor(s):  ______________________________________.
       
    22 ************************************************************************/
       
    23 
       
    24 p_message VARCHAR(2000);
       
    25 p_record_id VARCHAR(60);
       
    26 p_docAction VARCHAR(60);
       
    27 p_user VARCHAR(60);
       
    28 p_result NUMBER;
       
    29 
       
    30 v_PaidAmount NUMBER;
       
    31 V_OutstandingAmount NUMBER;
       
    32 V_DueAmount NUMBER;
       
    33 V_DayStillDue NUMBER;
       
    34 
       
    35 v_Client_ID VARCHAR2(32);
       
    36 v_Org_ID VARCHAR2(32);
       
    37 v_ResultStr VARCHAR2(2000):='';
       
    38 v_Message VARCHAR2(2000):='';
       
    39 v_DocTypeTarget_ID VARCHAR2(32);
       
    40 v_IsSOTrx C_INVOICE.IsSOTrx%TYPE;
       
    41 v_GrandTotal NUMBER:=0;
       
    42 v_PaymentTerm C_INVOICE.C_PaymentTerm_ID%TYPE;
       
    43 v_PaymentRule C_INVOICE.PaymentRule%TYPE;
       
    44 v_Currency_ID VARCHAR2(32);
       
    45 v_BPartner_ID VARCHAR2(32);
       
    46 v_DateInvoiced DATE;
       
    47 v_TotalLines NUMBER;
       
    48 v_PaymentMethod C_INVOICE.FIN_PAYMENTMETHOD_ID%TYPE;
       
    49 v_reversalinvoice_id VARCHAR2(32);
       
    50 v_delete_paymentplan BOOLEAN := FALSE;
       
    51 v_Financial_Account_ID FIN_FINANCIAL_ACCOUNT.FIN_FINANCIAL_ACCOUNT_ID%TYPE;
       
    52 v_CreatePayment CHAR(1):='N';
       
    53 v_CreateFinTransaction CHAR(1):='N';
       
    54 v_PaymentDocType_ID FIN_PAYMENT.C_DOCTYPE_ID%TYPE;
       
    55 v_PaymentDocumentNo FIN_PAYMENT.DOCUMENTNO%TYPE;
       
    56 v_FIN_PAYMENT_ID FIN_PAYMENT.FIN_PAYMENT_ID%TYPE;
       
    57 v_FIN_PAYMENT_DETAIL_ID FIN_PAYMENT_DETAIL.FIN_PAYMENT_DETAIL_ID%TYPE;
       
    58 v_FIN_FINACC_TRANSACTION_ID FIN_FINACC_TRANSACTION.FIN_FINACC_TRANSACTION_ID%TYPE;
       
    59 v_Line FIN_FINACC_TRANSACTION.LINE%TYPE;
       
    60 
       
    61 
       
    62 TYPE RECORD IS REF CURSOR;
       
    63 Cur_Params RECORD;
       
    64 cur_paymentschedule RECORD;
       
    65 cur_finaccpaymentmethod RECORD;
       
    66 cur_PaymentScheduleOrder RECORD;
       
    67 
       
    68 BEGIN
       
    69 
       
    70   FOR Cur_Params IN (
       
    71     SELECT *
       
    72     FROM ad_ep_instance_para
       
    73     WHERE ad_ep_instance_id = p_ep_instance
       
    74     ) LOOP
       
    75     IF (cur_params.parametername LIKE 'DocAction') THEN
       
    76       p_docaction := Cur_Params.p_string;
       
    77     ELSIF (cur_params.parametername LIKE 'Record_ID') THEN
       
    78       p_record_id := cur_params.p_string;
       
    79     ELSIF (cur_params.parametername LIKE 'User') THEN
       
    80       p_user := cur_params.p_string;
       
    81     ELSIF (cur_params.parametername LIKE 'Message') THEN
       
    82       p_message := cur_params.p_text;
       
    83     ELSIF (cur_params.parametername LIKE 'Result') THEN
       
    84       p_result := cur_params.p_number;
       
    85     END IF;
       
    86   END LOOP;
       
    87 
       
    88   -- Reading the invoice
       
    89   v_ResultStr:='ReadingInvoice';
       
    90   SELECT ad_client_id, ad_org_id, c_doctypetarget_id, IsSOTrx,
       
    91       grandtotal, C_PaymentTerm_ID, PaymentRule, C_Currency_ID,
       
    92       C_BPartner_ID, DateInvoiced, totallines, fin_paymentmethod_id
       
    93   INTO v_Client_ID, v_Org_ID, v_DocTypeTarget_ID, v_IsSOTrx,
       
    94       v_GrandTotal, v_PaymentTerm, v_PaymentRule, v_Currency_ID,
       
    95       v_BPartner_ID, v_DateInvoiced, v_totallines, v_PaymentMethod
       
    96   FROM c_invoice
       
    97   WHERE c_invoice_id=p_record_id;
       
    98 
       
    99   -- complete invoice
       
   100   IF (p_docaction = 'CO') THEN
       
   101     -- Checking Payment Method ID is available
       
   102     IF(v_PaymentMethod IS NULL) THEN
       
   103       RAISE_APPLICATION_ERROR(-20000, '@APRM_PAYMENTMETHOD_MISSING@');
       
   104     END IF;
       
   105 
       
   106     DECLARE
       
   107       cur_payments RECORD;
       
   108       cur_order_schdet_ISOPEN BOOLEAN:=false;
       
   109       fetch_next_order_item BOOLEAN:=true;
       
   110       v_TargetDocBaseType C_DOCTYPE.DocBaseType%TYPE;
       
   111       v_MultiplierARC NUMBER:=1;
       
   112       v_pendingAmount NUMBER;
       
   113       v_plannedDate DATE;
       
   114       v_paymentAmount NUMBER;
       
   115       v_scheduledamount NUMBER;
       
   116       v_invoicedamount NUMBER;
       
   117       v_notassignedamount NUMBER;
       
   118       v_assignedamount NUMBER;
       
   119       v_scheduledetailamount NUMBER;
       
   120       v_oldorder VARCHAR2(32) := '-1';
       
   121       v_payment_schedule_invoice VARCHAR2(32);
       
   122       v_differenceamount NUMBER:= 0;
       
   123       v_scheduledetailid VARCHAR2(32);
       
   124       v_new_scheduledetailid VARCHAR2(32);
       
   125       v_count NUMBER;
       
   126 
       
   127       CURSOR cur_order_schdet (invoice_id VARCHAR) IS
       
   128       SELECT c_orderline.c_order_id AS order_id, fin_payment_scheduledetail.amount + COALESCE(fin_payment_scheduledetail.writeoffamt,0) AS amount,
       
   129              fin_payment_scheduledetail_id,
       
   130              fin_payment_scheduledetail.fin_payment_schedule_order,
       
   131              fin_payment_scheduledetail.fin_payment_detail_id,
       
   132              CASE WHEN fin_payment_scheduledetail.fin_payment_detail_id is not null THEN 'Y' ELSE 'N' END AS paid
       
   133       FROM c_invoiceline, c_orderline, fin_payment_schedule, fin_payment_scheduledetail
       
   134       WHERE c_invoiceline.c_orderline_id = c_orderline.c_orderline_id
       
   135         AND c_orderline.c_order_id = fin_payment_schedule.c_order_id
       
   136         AND fin_payment_schedule.fin_payment_schedule_id = fin_payment_scheduledetail.fin_payment_schedule_order
       
   137         AND fin_payment_scheduledetail.fin_payment_schedule_invoice is null
       
   138         AND c_invoiceline.c_invoice_id = invoice_id
       
   139       ORDER BY CASE WHEN fin_payment_scheduledetail.fin_payment_detail_id is not null THEN 0 ELSE 1 END, c_orderline.c_order_id;
       
   140       order_schdet cur_order_schdet%ROWTYPE;
       
   141       next_order BOOLEAN := FALSE;
       
   142 
       
   143     BEGIN
       
   144       v_ResultStr:='Generating FIN_PAYMENT_SCHEDULE';
       
   145 
       
   146       SELECT count(1) INTO v_count
       
   147       FROM c_debt_payment, c_orderline, c_invoiceline
       
   148       WHERE c_debt_payment.c_order_id = c_orderline.c_order_id
       
   149         AND c_orderline.c_orderline_id = c_invoiceline.c_orderline_id
       
   150         AND c_invoiceline.c_invoice_id = p_record_id;
       
   151       IF (v_count > 0) THEN
       
   152         RAISE_APPLICATION_ERROR(-20000, '@APRM_INVOICED_ORDER_MAN_PAYMENTS@');
       
   153       END IF;
       
   154       SELECT count(1) INTO v_count
       
   155       FROM c_debt_payment
       
   156       WHERE c_invoice_id = p_record_id;
       
   157       IF (v_count > 0) THEN
       
   158         RAISE_APPLICATION_ERROR(-20000, '@APRM_INVOICE_MAN_PAYMENTS@');
       
   159       END IF;
       
   160       -- Is it a Credit Memo
       
   161       SELECT docbasetype
       
   162         INTO v_TargetDocBaseType
       
   163       FROM c_doctype
       
   164       WHERE c_doctype_id=v_DocTypeTarget_ID;
       
   165       IF v_TargetDocBaseType in ('ARC','APC') THEN
       
   166         v_MultiplierARC:=-1;
       
   167       END IF;
       
   168 
       
   169       --Insert Payment Schedules for Invoices
       
   170       v_pendingAmount:=v_GrandTotal;
       
   171 
       
   172       FOR cur_payments IN (
       
   173           SELECT line, percentage, onremainder, excludetax,
       
   174                  COALESCE(paymentrule, v_paymentrule) AS paymentrule,
       
   175                  fixmonthday, fixmonthday2, fixmonthday3, netdays,
       
   176                  fixmonthoffset, netday, isnextbusinessday
       
   177           FROM c_paymenttermline
       
   178           WHERE c_paymentterm_id=v_paymentterm
       
   179             AND isactive = 'Y'
       
   180           UNION
       
   181           -- Header of paymentTerm is processed at last
       
   182           SELECT 9999 AS line, 100 AS percentage, 'Y' AS onremainder, 'N' AS excludetax,
       
   183                  v_paymentRule AS paymentrule,
       
   184                  fixmonthday, fixmonthday2, fixmonthday3, netdays,
       
   185                  fixmonthoffset, netday, isnextbusinessday
       
   186           FROM c_paymentterm
       
   187           WHERE c_paymentterm_id=v_paymentterm
       
   188           ORDER BY line
       
   189         )
       
   190       LOOP
       
   191         v_plannedDate:=C_Paymentduedate(v_bpartner_id, v_issotrx, cur_payments.fixmonthday, cur_payments.fixmonthday2, cur_payments.fixmonthday3, cur_payments.netdays, cur_payments.fixmonthoffset, cur_payments.netday, cur_payments.isnextbusinessday, v_dateinvoiced);
       
   192 
       
   193         IF(cur_payments.excludetax='Y') THEN
       
   194           -- if excludeTax = 'Y', percentage is aplied on the TotalLines
       
   195           v_paymentAmount:=C_Currency_Round(v_totallines * cur_payments.percentage/100, v_currency_id, NULL);
       
   196         ELSIF(cur_payments.onremainder='N') THEN
       
   197           -- if onRemainder = 'N', percentage is aplied on the GrandTotal
       
   198           v_paymentAmount:=C_Currency_Round(v_grandtotal * cur_payments.percentage/100, v_currency_id, NULL);
       
   199         ELSE
       
   200           v_paymentAmount:=C_Currency_Round(v_pendingamount * cur_payments.percentage/100, v_currency_id, NULL);
       
   201         END IF;
       
   202         v_pendingamount := v_pendingamount - v_paymentamount;
       
   203         v_scheduledamount := C_Currency_Round((v_paymentamount * v_multiplierarc), v_currency_id, NULL);
       
   204 
       
   205         v_ResultStr:='Inserting in FIN_PAYMENT_SCHEDULE table';
       
   206 
       
   207         v_payment_schedule_invoice := get_uuid();
       
   208         INSERT INTO fin_payment_schedule
       
   209         (
       
   210           fin_payment_schedule_id, ad_client_id, ad_org_id, isactive,
       
   211           created, createdby, updated, updatedby,
       
   212           c_invoice_id, c_currency_id, c_order_id,
       
   213           fin_paymentmethod_id, amount, duedate,
       
   214           outstandingamt
       
   215          ) VALUES (
       
   216           v_payment_schedule_invoice, v_client_id, v_org_id, 'Y',
       
   217           now(), p_user, now(), p_user,
       
   218           p_record_id, v_currency_id, null,
       
   219           v_PaymentMethod,
       
   220           v_scheduledamount, v_planneddate,
       
   221           v_scheduledamount
       
   222         );
       
   223 
       
   224         -- loop for payment schedule details
       
   225         LOOP
       
   226           -- open cursor once
       
   227           IF (NOT cur_order_schdet_ISOPEN) THEN
       
   228             OPEN cur_order_schdet(p_record_id);
       
   229             cur_order_schdet_ISOPEN := true;
       
   230           END IF;
       
   231 
       
   232           -- fetch if we have finished with the current one
       
   233           IF (fetch_next_order_item OR next_order) THEN
       
   234             FETCH cur_order_schdet INTO order_schdet;
       
   235             EXIT WHEN cur_order_schdet%NOTFOUND;
       
   236             v_scheduledetailid := order_schdet.fin_payment_scheduledetail_id;
       
   237             v_scheduledetailamount := order_schdet.amount;
       
   238           ELSE
       
   239             v_scheduledetailamount := v_differenceamount;
       
   240             v_scheduledetailid := v_new_scheduledetailid;
       
   241           END IF;
       
   242 
       
   243           IF (order_schdet.order_id <> v_oldorder) THEN
       
   244             next_order := FALSE;
       
   245             -- get invoiced amount for the order
       
   246             SELECT SUM(c_invoiceline.linenetamt+c_getinvoiceline_taxamount(c_invoiceline.c_invoiceline_id)) INTO v_invoicedamount
       
   247             FROM c_invoiceline, c_orderline
       
   248             WHERE c_invoiceline.c_orderline_id = c_orderline.c_orderline_id
       
   249               AND c_invoiceline.c_invoice_id = p_record_id
       
   250               AND c_orderline.c_order_id = order_schdet.order_id;
       
   251             -- substract previously assigned amount
       
   252             SELECT SUM(psd.amount) INTO v_assignedamount
       
   253             FROM fin_payment_schedule ps_inv, fin_payment_scheduledetail psd,
       
   254                  fin_payment_schedule ps_ord
       
   255             WHERE ps_inv.fin_payment_schedule_id = psd.fin_payment_schedule_invoice
       
   256               AND psd.fin_payment_schedule_order = ps_ord.fin_payment_schedule_id
       
   257               AND ps_inv.c_invoice_id = p_record_id
       
   258               AND ps_ord.c_order_id = order_schdet.order_id;
       
   259 
       
   260             v_notassignedamount := COALESCE(v_invoicedamount,0) - COALESCE(v_assignedamount,0);
       
   261           END IF;
       
   262 
       
   263           IF (v_notassignedamount <= 0) THEN
       
   264             next_order := TRUE;
       
   265           END IF;
       
   266           -- create a new payment schedule detail if necessary
       
   267           IF (NOT next_order) THEN
       
   268             v_differenceamount := 0;
       
   269             IF ((v_notassignedamount <= v_scheduledamount) AND (v_notassignedamount < v_scheduledetailamount)) THEN
       
   270               v_differenceamount := COALESCE(v_scheduledetailamount,0) - COALESCE(v_notassignedamount,0);
       
   271             ELSIF ((v_scheduledamount < v_notassignedamount) AND (v_scheduledamount < v_scheduledetailamount)) THEN
       
   272               v_differenceamount := COALESCE(v_scheduledetailamount,0) - COALESCE(v_scheduledamount,0);
       
   273             END IF;
       
   274 
       
   275             SELECT COUNT(*) INTO v_Count
       
   276             FROM c_orderline
       
   277             WHERE qtyinvoiced<>qtyordered
       
   278             AND c_order_id = order_schdet.order_id;
       
   279 
       
   280             IF(v_Count=0) THEN
       
   281 		v_differenceamount:= 0;
       
   282             END IF;
       
   283 
       
   284             IF (v_differenceamount > 0) THEN
       
   285                 -- continue with the same payment schedule detail
       
   286                 fetch_next_order_item := false;
       
   287                 v_new_scheduledetailid := get_uuid();
       
   288                 INSERT INTO fin_payment_scheduledetail
       
   289                 (
       
   290                   fin_payment_scheduledetail_id, ad_client_id, ad_org_id, isactive,
       
   291                   created, createdby, updated, updatedby,
       
   292                   fin_payment_schedule_order,
       
   293                   fin_payment_schedule_invoice,
       
   294                   fin_payment_detail_id,
       
   295                   amount
       
   296                 )
       
   297                 VALUES
       
   298                 (
       
   299                   v_new_scheduledetailid, v_Client_ID, v_Org_ID, 'Y',
       
   300                   now(), p_user, now(), p_user,
       
   301                   order_schdet.fin_payment_schedule_order,
       
   302                   null,
       
   303                   order_schdet.fin_payment_detail_id,
       
   304                   v_differenceamount
       
   305                 );
       
   306                 -- update amount of the current payment schedule detail
       
   307                 UPDATE fin_payment_scheduledetail
       
   308                 SET amount = amount - v_differenceamount,
       
   309                   updated = now(),
       
   310                   updatedby = p_user
       
   311                 WHERE fin_payment_scheduledetail_id = v_scheduledetailid;
       
   312 
       
   313                 v_scheduledetailamount := v_scheduledetailamount - v_differenceamount;
       
   314 
       
   315             ELSE
       
   316                 fetch_next_order_item := true;
       
   317             END IF;
       
   318 
       
   319             -- link current current payment schedule detail to the invoice
       
   320             UPDATE fin_payment_scheduledetail
       
   321             SET fin_payment_schedule_invoice = v_payment_schedule_invoice,
       
   322                 updated = now(),
       
   323                 updatedby = p_user
       
   324             WHERE fin_payment_scheduledetail_id = v_scheduledetailid;
       
   325 
       
   326             -- if paid, update paid and outstanding amount
       
   327             IF (order_schdet.paid = 'Y') THEN
       
   328               UPDATE fin_payment_schedule
       
   329               SET outstandingamt = outstandingamt - COALESCE(v_scheduledetailamount,0),
       
   330                   paidamt = paidamt + COALESCE(v_scheduledetailamount, 0)
       
   331               WHERE fin_payment_schedule_id = v_payment_schedule_invoice;
       
   332             END IF;
       
   333 
       
   334             v_notassignedamount := v_notassignedamount - v_scheduledetailamount;
       
   335             v_scheduledamount := v_scheduledamount - v_scheduledetailamount;
       
   336 
       
   337             IF (v_scheduledamount <= 0) THEN
       
   338               -- actual payment processed.
       
   339               v_oldorder := order_schdet.order_id;
       
   340               EXIT;
       
   341             END IF;
       
   342           END IF;
       
   343 
       
   344           v_oldorder := order_schdet.order_id;
       
   345         END LOOP;
       
   346 
       
   347         IF (v_scheduledamount != 0 ) THEN
       
   348           -- no orders, insert payment schedule detail with remaining amount
       
   349           INSERT INTO fin_payment_scheduledetail
       
   350           (
       
   351             fin_payment_scheduledetail_id, ad_client_id, ad_org_id, isactive,
       
   352             created, createdby, updated, updatedby,
       
   353             fin_payment_schedule_order,
       
   354             fin_payment_schedule_invoice,
       
   355             fin_payment_detail_id,
       
   356             amount
       
   357           )
       
   358           VALUES
       
   359           (
       
   360             get_uuid(), v_Client_ID, v_Org_ID, 'Y',
       
   361             now(), p_user, now(), p_user,
       
   362             null,
       
   363             v_payment_schedule_invoice,
       
   364             null,
       
   365             v_scheduledamount
       
   366           );
       
   367         END IF;
       
   368       END LOOP;
       
   369 
       
   370       CLOSE cur_order_schdet;
       
   371 
       
   372       -- Reading Data from FIN_PAYMENT_SCHEDULE
       
   373       SELECT sum(PAIDAMT) as PaidAmount, SUM(OUTSTANDINGAMT) as OutstandingAmount
       
   374         INTO v_PaidAmount,V_OutstandingAmount
       
   375       FROM FIN_PAYMENT_SCHEDULE
       
   376       WHERE C_INVOICE_ID=P_RECORD_ID;
       
   377       -- Getting DueAmount from FIN_PAYMENT_SCHEDULE for the Invoice
       
   378       SELECT sum(OUTSTANDINGAMT) as DueAmount
       
   379         INTO V_DueAmount
       
   380       FROM FIN_PAYMENT_SCHEDULE
       
   381       WHERE C_INVOICE_ID=P_RECORD_ID
       
   382         AND duedate<=now();
       
   383       V_DueAmount :=COALESCE(V_DueAmount,0);
       
   384       --Getting Day Still Due
       
   385       SELECT COALESCE(TO_NUMBER(MIN(DUEDATE)-TRUNC(now())),0) as DAYSTILLDUE
       
   386       INTO V_DayStillDue
       
   387       FROM FIN_PAYMENT_SCHEDULE
       
   388       WHERE C_INVOICE_ID=P_RECORD_ID
       
   389         AND OUTSTANDINGAMT != 0;
       
   390 
       
   391       --Updating Payment Monitor values into C_INVOICE
       
   392       UPDATE C_INVOICE
       
   393       SET TOTALPAID = v_PaidAmount,
       
   394           OUTSTANDINGAMT = COALESCE(v_OutstandingAmount,0),
       
   395           DUEAMT =  V_DueAmount,
       
   396           DAYSTILLDUE = V_DayStillDue,
       
   397           LASTCALCULATEDONDATE = now(),
       
   398           ISPAID = CASE v_OutstandingAmount WHEN 0 THEN 'Y' ELSE 'N' END
       
   399       WHERE C_INVOICE_ID = P_RECORD_ID;
       
   400 
       
   401       -- Updating SO_CREDITUSED when Invoices are being processed
       
   402       UPDATE C_BPARTNER
       
   403       SET SO_CREDITUSED = COALESCE(SO_CREDITUSED,0) + V_OutstandingAmount
       
   404       WHERE C_BPARTNER_ID = v_BPartner_ID;
       
   405 
       
   406       -- Automatic creation of payment and financial transaction
       
   407       SELECT CASE WHEN v_IsSOTrx='Y' THEN FIN_FINANCIAL_ACCOUNT_ID ELSE PO_FINANCIAL_ACCOUNT_ID END
       
   408         INTO v_Financial_Account_ID
       
   409       FROM C_BPARTNER
       
   410       WHERE C_BPARTNER_ID = v_BPartner_ID;
       
   411       IF(v_Financial_Account_ID IS NOT NULL) THEN
       
   412         FOR cur_paymentschedule IN (
       
   413             SELECT C_INVOICE.C_BPARTNER_ID, C_INVOICE.DOCUMENTNO, FIN_PAYMENT_SCHEDULE.FIN_PAYMENTMETHOD_ID,
       
   414               FIN_PAYMENT_SCHEDULE.OUTSTANDINGAMT, AMOUNT, ISSOTRX, DUEDATE,
       
   415               FIN_PAYMENT_SCHEDULE.C_CURRENCY_ID,
       
   416               C_PROJECT_ID, C_CAMPAIGN_ID, C_ACTIVITY_ID, USER1_ID, USER2_ID, FIN_PAYMENT_SCHEDULE.C_INVOICE_ID,
       
   417               FIN_PAYMENT_SCHEDULE.AD_CLIENT_ID, FIN_PAYMENT_SCHEDULE.AD_ORG_ID, FIN_PAYMENT_SCHEDULE_ID
       
   418             FROM FIN_PAYMENT_SCHEDULE, C_INVOICE
       
   419             WHERE FIN_PAYMENT_SCHEDULE.C_INVOICE_ID = C_INVOICE.C_INVOICE_ID
       
   420               AND C_INVOICE.C_INVOICE_ID = P_RECORD_ID
       
   421               AND FIN_PAYMENT_SCHEDULE.ISACTIVE = 'Y'
       
   422               AND FIN_PAYMENT_SCHEDULE.OUTSTANDINGAMT <> 0
       
   423             ORDER BY FIN_PAYMENT_SCHEDULE.DUEDATE, FIN_PAYMENT_SCHEDULE_ID
       
   424           )
       
   425         LOOP
       
   426           FOR cur_finaccpaymentmethod IN (
       
   427               SELECT CASE WHEN v_IsSOTrx='Y' THEN AUTOMATIC_RECEIPT ELSE AUTOMATIC_PAYMENT END AS CreatePayment,
       
   428                 CASE WHEN v_IsSOTrx='Y' THEN AUTOMATIC_DEPOSIT ELSE AUTOMATIC_WITHDRAWN END AS CreateFinTransaction,
       
   429                 CASE WHEN v_IsSOTrx='Y' THEN payin_execution_type ELSE payout_execution_type END AS ExecutionType,
       
   430                 CASE WHEN v_IsSOTrx='Y' THEN payin_deferred ELSE payout_deferred END AS deferred,
       
   431                 CASE WHEN v_IsSOTrx='Y' THEN payin_execution_process_id ELSE payout_execution_process_id END AS execution_process_id
       
   432               FROM FIN_FINACC_PAYMENTMETHOD
       
   433               WHERE FIN_FINACC_PAYMENTMETHOD.FIN_PAYMENTMETHOD_ID = cur_paymentschedule.FIN_PAYMENTMETHOD_ID
       
   434                 AND FIN_FINACC_PAYMENTMETHOD.FIN_FINANCIAL_ACCOUNT_ID = v_Financial_Account_ID
       
   435                 AND FIN_FINACC_PAYMENTMETHOD.ISACTIVE='Y'
       
   436             )
       
   437           LOOP
       
   438             -- Automatic creation of payment
       
   439             IF(cur_finaccpaymentmethod.CreatePayment = 'Y') THEN
       
   440               v_ResultStr:='Generating FIN_PAYMENT';
       
   441               v_FIN_PAYMENT_ID := GET_UUID();
       
   442               v_PaymentDocType_ID := AD_GET_DOCTYPE(cur_paymentschedule.AD_CLIENT_ID, cur_paymentschedule.AD_ORG_ID, CASE WHEN v_IsSOTrx='Y' THEN 'ARR' ELSE 'APP' END);
       
   443               AD_SEQUENCE_DOCTYPE(v_PaymentDocType_ID, cur_paymentschedule.AD_CLIENT_ID, 'Y', v_PaymentDocumentNo);
       
   444               IF (v_PaymentDocumentNo IS NULL) THEN
       
   445                 AD_SEQUENCE_DOC('DocumentNo_FIN_Payment', cur_paymentschedule.AD_CLIENT_ID, 'Y', v_PaymentDocumentNo);
       
   446               END IF;
       
   447               INSERT INTO fin_payment(
       
   448                 fin_payment_id, ad_client_id, ad_org_id, created, createdby,
       
   449                 updated, updatedby, isactive, isreceipt, c_bpartner_id, paymentdate,
       
   450                 c_currency_id, amount, writeoffamt, fin_paymentmethod_id, documentno,
       
   451                 referenceno,
       
   452                 status,
       
   453                 processed, processing, posted, description,
       
   454                 fin_financial_account_id, c_doctype_id, c_project_id, c_campaign_id,
       
   455                 c_activity_id, user1_id, user2_id, em_aprm_process_payment, em_aprm_reconcile_payment,
       
   456                 em_aprm_add_scheduledpayments)
       
   457               VALUES (v_FIN_PAYMENT_ID, cur_paymentschedule.AD_CLIENT_ID, cur_paymentschedule.AD_ORG_ID, now(), p_user,
       
   458                 now(), p_user, 'Y', v_IsSOTrx, cur_paymentschedule.C_BPARTNER_ID, cur_paymentschedule.DUEDATE,
       
   459                 cur_paymentschedule.C_CURRENCY_ID, COALESCE(cur_paymentschedule.OUTSTANDINGAMT,0), 0, cur_paymentschedule.FIN_PAYMENTMETHOD_ID, v_PaymentDocumentNo,
       
   460                 '',
       
   461                 CASE
       
   462                   WHEN cur_finaccpaymentmethod.ExecutionType = 'A' THEN 'RPAE'
       
   463                   WHEN v_IsSOTrx = 'Y' THEN 'RPR'
       
   464                   ELSE 'PPM'
       
   465                 END,
       
   466                 'N', 'N', 'N', 'Invoice No.: ' || cur_paymentschedule.DOCUMENTNO,
       
   467                 v_Financial_Account_ID, v_PaymentDocType_ID, cur_paymentschedule.C_PROJECT_ID, cur_paymentschedule.C_CAMPAIGN_ID,
       
   468                 cur_paymentschedule.C_ACTIVITY_ID, cur_paymentschedule.USER1_ID, cur_paymentschedule.USER2_ID, 'N', 'N', 'N');
       
   469               v_FIN_PAYMENT_DETAIL_ID := GET_UUID();
       
   470               INSERT INTO fin_payment_detail(
       
   471                 fin_payment_detail_id, ad_client_id, ad_org_id, created, createdby,
       
   472                 updated, updatedby, fin_payment_id, amount, refund, isactive,
       
   473                 writeoffamt, c_glitem_id, isprepayment)
       
   474                   VALUES (v_FIN_PAYMENT_DETAIL_ID, cur_paymentschedule.AD_CLIENT_ID, cur_paymentschedule.AD_ORG_ID, now(), p_user,
       
   475                 now(), p_user, v_FIN_PAYMENT_ID, cur_paymentschedule.OUTSTANDINGAMT, 'N', 'Y',
       
   476                 0, NULL, 'N');
       
   477 
       
   478               --Fixes 14403 defect 
       
   479               -- Payment document id is added in success message when invoice is completed with auto receipt is checked
       
   480               v_Message:='@APRM_PaymentDocumentno@ ' || v_PaymentDocumentNo || ' @beenCreated@';
       
   481               UPDATE ad_ep_instance_para SET p_text= v_Message WHERE ad_ep_instance_id= p_ep_instance AND parametername LIKE 'Message';
       
   482 
       
   483               IF (cur_finaccpaymentmethod.deferred = 'N'
       
   484                   AND cur_finaccpaymentmethod.ExecutionType='A') THEN
       
   485                 INSERT INTO aprm_pending_paymentinvoice (
       
   486                   aprm_pending_paymentinvoice_id, ad_client_id, ad_org_id, isactive,
       
   487                   created, createdby, updated, updatedby,
       
   488                   processing, fin_payment_id, c_invoice_id, fin_pay_exec_process_id
       
   489                 ) VALUES (
       
   490                   get_uuid(), v_client_id, v_org_id, 'Y',
       
   491                   now(), p_user, now(), p_user,
       
   492                   'N', v_fin_payment_id, p_record_id, cur_finaccpaymentmethod.execution_process_id);
       
   493               END IF;
       
   494 
       
   495               UPDATE FIN_PAYMENT_SCHEDULEDETAIL SET FIN_PAYMENT_DETAIL_ID = v_FIN_PAYMENT_DETAIL_ID
       
   496                 WHERE FIN_PAYMENT_SCHEDULE_INVOICE = cur_paymentschedule.FIN_PAYMENT_SCHEDULE_ID
       
   497                   AND FIN_PAYMENT_DETAIL_ID IS NULL;
       
   498               FOR cur_PaymentScheduleOrder IN (
       
   499                  SELECT FIN_PAYMENT_SCHEDULE_ORDER
       
   500                  FROM FIN_PAYMENT_SCHEDULEDETAIL
       
   501                  WHERE FIN_PAYMENT_SCHEDULE_INVOICE = cur_paymentschedule.FIN_PAYMENT_SCHEDULE_ID
       
   502                  AND FIN_PAYMENT_SCHEDULE_ORDER IS NOT NULL
       
   503                  GROUP BY FIN_PAYMENT_SCHEDULE_ORDER
       
   504               ) LOOP
       
   505                 UPDATE FIN_PAYMENT_SCHEDULE SET PAIDAMT = PAIDAMT + cur_paymentschedule.OUTSTANDINGAMT , OUTSTANDINGAMT=OUTSTANDINGAMT-cur_paymentschedule.OUTSTANDINGAMT
       
   506                 WHERE FIN_PAYMENT_SCHEDULE_ID = cur_PaymentScheduleOrder.FIN_PAYMENT_SCHEDULE_ORDER;
       
   507               END LOOP;
       
   508               UPDATE FIN_PAYMENT_SCHEDULE SET PAIDAMT = PAIDAMT + COALESCE(cur_paymentschedule.OUTSTANDINGAMT,0) , OUTSTANDINGAMT=0
       
   509                 WHERE FIN_PAYMENT_SCHEDULE_ID = cur_paymentschedule.FIN_PAYMENT_SCHEDULE_ID;
       
   510               UPDATE FIN_PAYMENT SET PROCESSED = 'Y', EM_APRM_PROCESS_PAYMENT = 'R'
       
   511                 WHERE FIN_PAYMENT_ID = v_FIN_PAYMENT_ID;
       
   512               UPDATE C_INVOICE SET TOTALPAID = TOTALPAID + COALESCE(cur_paymentschedule.OUTSTANDINGAMT, 0), OUTSTANDINGAMT = 0, DUEAMT = DUEAMT - COALESCE(cur_paymentschedule.OUTSTANDINGAMT, 0)
       
   513               WHERE C_INVOICE_ID = P_RECORD_ID;
       
   514               UPDATE C_INVOICE SET ISPAID = 'Y'
       
   515               WHERE C_INVOICE_ID = P_RECORD_ID
       
   516                 AND TOTALPAID = GRANDTOTAL;
       
   517               -- Updating SO_CREDITUSED when PAYMENT OCCUR
       
   518               UPDATE C_BPARTNER
       
   519               SET SO_CREDITUSED = COALESCE(SO_CREDITUSED,0) - COALESCE(cur_paymentschedule.OUTSTANDINGAMT, 0)
       
   520               WHERE C_BPARTNER_ID = v_BPartner_ID;
       
   521 
       
   522               -- Automatic creation of financial transaction
       
   523               IF(cur_finaccpaymentmethod.CreateFinTransaction = 'Y' AND cur_finaccpaymentmethod.ExecutionType = 'M') THEN
       
   524                 v_ResultStr:='Generating FIN_FINACC_TRANSACTION';
       
   525                 v_FIN_FINACC_TRANSACTION_ID := GET_UUID();
       
   526                 SELECT COALESCE(MAX(LINE),0) INTO v_Line FROM FIN_FINACC_TRANSACTION WHERE FIN_FINANCIAL_ACCOUNT_ID = v_Financial_Account_ID;
       
   527                 INSERT INTO fin_finacc_transaction(
       
   528                   fin_finacc_transaction_id, ad_client_id, ad_org_id, created,
       
   529                   createdby, updated, updatedby, isactive, c_currency_id, fin_financial_account_id,
       
   530                   line, fin_payment_id, dateacct, c_glitem_id, status, paymentamt,
       
   531                   depositamt, processed, processing, posted, c_project_id, c_campaign_id,
       
   532                   c_activity_id, user1_id, user2_id, trxtype, statementdate, description,
       
   533                   fin_reconciliation_id)
       
   534                 VALUES (v_FIN_FINACC_TRANSACTION_ID, cur_paymentschedule.AD_CLIENT_ID, cur_paymentschedule.AD_ORG_ID, now(), p_user,
       
   535                   now(), p_user, 'Y', cur_paymentschedule.C_CURRENCY_ID, v_Financial_Account_ID,
       
   536                   v_Line, v_FIN_PAYMENT_ID, cur_paymentschedule.DUEDATE, NULL, CASE WHEN v_IsSOTrx='Y' THEN 'RDNC' ELSE 'PWNC' END, CASE WHEN v_IsSOTrx='N' THEN cur_paymentschedule.OUTSTANDINGAMT ELSE 0 END,
       
   537                   CASE WHEN v_IsSOTrx='Y' THEN cur_paymentschedule.OUTSTANDINGAMT ELSE 0 END, 'Y', 'N', 'N', cur_paymentschedule.C_PROJECT_ID, cur_paymentschedule.C_CAMPAIGN_ID,
       
   538                   cur_paymentschedule.C_ACTIVITY_ID, cur_paymentschedule.USER1_ID, cur_paymentschedule.USER2_ID, CASE WHEN v_IsSOTrx='N' THEN 'BPW' ELSE 'BPD' END, cur_paymentschedule.DUEDATE, 'Invoice No.: ' || cur_paymentschedule.DOCUMENTNO,
       
   539                   NULL);
       
   540                 UPDATE FIN_PAYMENT SET STATUS = CASE WHEN v_IsSOTrx='Y' THEN 'RDNC' ELSE 'PWNC' END
       
   541                   WHERE FIN_PAYMENT_ID = v_FIN_PAYMENT_ID;
       
   542                   --UPDATE FINANCIAL ACCOUNT CURRENT BALANCE
       
   543                   UPDATE FIN_FINANCIAL_ACCOUNT SET CURRENTBALANCE=CURRENTBALANCE + (CASE WHEN v_IsSOTrx='Y' THEN cur_paymentschedule.OUTSTANDINGAMT ELSE (cur_paymentschedule.OUTSTANDINGAMT*-1) END)
       
   544                   WHERE FIN_FINANCIAL_ACCOUNT_ID = v_Financial_Account_ID;
       
   545               END IF;
       
   546             END IF;
       
   547           END LOOP;
       
   548         END LOOP;
       
   549       END IF;
       
   550     END;
       
   551 
       
   552   ELSIF (p_docaction = 'RE') THEN
       
   553     DECLARE
       
   554       v_count NUMBER;
       
   555       v_documentno VARCHAR2(40);
       
   556     BEGIN
       
   557       SELECT count(*), max(p.documentno)
       
   558         INTO v_count, v_documentno
       
   559       FROM fin_payment_schedule ps, fin_payment_scheduledetail psd, fin_payment_detail pd, fin_payment p
       
   560       WHERE ps.fin_payment_schedule_id = psd.fin_payment_schedule_invoice
       
   561         AND ps.c_invoice_id = p_record_id
       
   562         AND psd.fin_payment_detail_id = pd.fin_payment_detail_id
       
   563         AND pd.fin_payment_id = p.fin_payment_id
       
   564         AND pd.isprepayment = 'N';
       
   565       IF (v_count <> 0) THEN
       
   566         RAISE_APPLICATION_ERROR(-20000, '@APRM_InvoiceWithPayments@' || ' ' || v_documentno);
       
   567       END IF;
       
   568       SELECT count(*), max(p.documentno)
       
   569         INTO v_count, v_documentno
       
   570       FROM fin_payment_schedule ps, fin_payment_scheduledetail psd, fin_payment_prop_detail pd, fin_payment_proposal p
       
   571       WHERE ps.fin_payment_schedule_id = psd.fin_payment_schedule_invoice
       
   572         AND ps.c_invoice_id = p_record_id
       
   573         AND psd.fin_payment_scheduledetail_id = pd.fin_payment_scheduledetail_id
       
   574         AND pd.fin_payment_proposal_id = p.fin_payment_proposal_id
       
   575         AND psd.fin_payment_detail_id is null;
       
   576       IF (v_count <> 0) THEN
       
   577         RAISE_APPLICATION_ERROR(-20000, '@APRM_InvoiceWithUnprocessedProposal@' || ' ' || v_documentno);
       
   578       END IF;
       
   579       v_delete_paymentplan := TRUE;
       
   580 
       
   581       SELECT SUM(FIN_PAYMENT_SCHEDULEDETAIL.AMOUNT) INTO v_PaidAmount
       
   582       FROM FIN_PAYMENT_SCHEDULEDETAIL, FIN_PAYMENT_SCHEDULE
       
   583       WHERE FIN_PAYMENT_DETAIL_ID IS NOT NULL
       
   584       AND FIN_PAYMENT_SCHEDULEDETAIL.FIN_PAYMENT_SCHEDULE_INVOICE = FIN_PAYMENT_SCHEDULE.FIN_PAYMENT_SCHEDULE_ID
       
   585       AND FIN_PAYMENT_SCHEDULE.C_INVOICE_ID = p_record_id;
       
   586 
       
   587       -- Updating SO_CREDITUSED when Payments are being processed
       
   588       UPDATE C_BPARTNER
       
   589          SET SO_CREDITUSED = COALESCE(SO_CREDITUSED,0) - V_GrandTotal + v_PaidAmount
       
   590       WHERE C_BPARTNER_ID = v_BPartner_ID;
       
   591     END;
       
   592 
       
   593   ELSIF (p_docaction = 'RC') THEN
       
   594     DECLARE
       
   595       v_count NUMBER;
       
   596     BEGIN
       
   597       v_delete_paymentplan := TRUE;
       
   598       SELECT c_invoice_id INTO v_reversalinvoice_id
       
   599       FROM c_invoice_reverse
       
   600       WHERE reversed_c_invoice_id = p_record_id;
       
   601       SELECT count(*) INTO v_count
       
   602       FROM fin_payment_schedule ps, fin_payment_scheduledetail psd, fin_payment_detail pd, fin_payment p
       
   603       WHERE ps.fin_payment_schedule_id = psd.fin_payment_schedule_invoice
       
   604         AND ps.c_invoice_id = p_record_id
       
   605         AND psd.fin_payment_detail_id = pd.fin_payment_detail_id
       
   606         AND pd.fin_payment_id = p.fin_payment_id
       
   607         AND pd.isprepayment = 'N';
       
   608       IF (v_count <> 0) THEN
       
   609         v_delete_paymentplan := FALSE;
       
   610       END IF;
       
   611       SELECT count(*) INTO v_count
       
   612       FROM fin_payment_schedule ps, fin_payment_scheduledetail psd, fin_payment_prop_detail pd, fin_payment_proposal p
       
   613       WHERE ps.fin_payment_schedule_id = psd.fin_payment_schedule_invoice
       
   614         AND ps.c_invoice_id = p_record_id
       
   615         AND psd.fin_payment_scheduledetail_id = pd.fin_payment_scheduledetail_id
       
   616         AND pd.fin_payment_proposal_id = p.fin_payment_proposal_id
       
   617         AND psd.fin_payment_detail_id is null;
       
   618       IF (v_count <> 0) THEN
       
   619         v_delete_paymentplan := FALSE;
       
   620       END IF;
       
   621     END;
       
   622   END IF;
       
   623 
       
   624   IF (v_delete_paymentplan) THEN
       
   625     DECLARE
       
   626       v_payment_detail_old VARCHAR2(32);
       
   627       v_payment_scheduledetail_old VARCHAR2(32);
       
   628       cur_ps RECORD;
       
   629       cur_psd RECORD;
       
   630     BEGIN
       
   631       -- Delete schedule detail records that not belong to orders
       
   632       DELETE FROM fin_payment_scheduledetail
       
   633       WHERE fin_payment_schedule_invoice IN
       
   634           (SELECT fin_payment_schedule_id
       
   635            FROM fin_payment_schedule
       
   636            WHERE (c_invoice_id = p_record_id
       
   637                   OR
       
   638                   (v_reversalinvoice_id IS NOT NULL AND c_invoice_id = v_reversalinvoice_id)))
       
   639         AND fin_payment_schedule_order is null;
       
   640 
       
   641       FOR cur_ps IN (
       
   642         SELECT DISTINCT fin_payment_schedule_order
       
   643         FROM fin_payment_scheduledetail
       
   644         WHERE fin_payment_schedule_invoice IN
       
   645           (SELECT fin_payment_schedule_id
       
   646            FROM fin_payment_schedule
       
   647            WHERE (c_invoice_id = p_record_id
       
   648                   OR
       
   649                   (v_reversalinvoice_id IS NOT NULL AND c_invoice_id = v_reversalinvoice_id))))
       
   650         LOOP
       
   651 
       
   652         UPDATE fin_payment_scheduledetail
       
   653         SET fin_payment_schedule_invoice = null
       
   654         WHERE fin_payment_schedule_invoice IN
       
   655           (SELECT fin_payment_schedule_id
       
   656            FROM fin_payment_schedule
       
   657            WHERE (c_invoice_id = p_record_id
       
   658                   OR
       
   659                   (v_reversalinvoice_id IS NOT NULL AND c_invoice_id = v_reversalinvoice_id)))
       
   660           AND fin_payment_schedule_order = cur_ps.fin_payment_schedule_order;
       
   661         v_payment_detail_old := '-2';
       
   662         v_payment_scheduledetail_old := '-1';
       
   663 
       
   664         FOR cur_psd IN (SELECT fin_payment_scheduledetail_id, COALESCE(fin_payment_detail_id,'-1') as fin_payment_detail_id,
       
   665                                amount, writeoffamt
       
   666                         FROM fin_payment_scheduledetail
       
   667                         WHERE fin_payment_schedule_order = cur_ps.fin_payment_schedule_order
       
   668                         AND fin_payment_schedule_invoice IS NULL
       
   669                         ORDER BY fin_payment_detail_id, created)
       
   670           LOOP
       
   671           -- if there are more than one psd with same payment detail merge them.
       
   672           IF (cur_psd.fin_payment_detail_id = v_payment_detail_old) THEN
       
   673             UPDATE fin_payment_scheduledetail
       
   674             SET amount = amount + cur_psd.amount,
       
   675                 writeoffamt = COALESCE(writeoffamt,0) + COALESCE(cur_psd.writeoffamt,0),
       
   676                 updated = now(),
       
   677                 updatedby = p_user
       
   678             WHERE fin_payment_scheduledetail_id = v_payment_scheduledetail_old;
       
   679             DELETE FROM fin_payment_scheduledetail
       
   680             WHERE fin_payment_scheduledetail_id = cur_psd.fin_payment_scheduledetail_id;
       
   681           ELSE
       
   682             v_payment_detail_old := COALESCE(cur_psd.fin_payment_detail_id,'-1');
       
   683             v_payment_scheduledetail_old := cur_psd.fin_payment_scheduledetail_id;
       
   684           END IF;
       
   685         END LOOP;
       
   686       END LOOP;
       
   687 
       
   688       DELETE FROM fin_payment_schedule WHERE (c_invoice_id = p_record_id
       
   689                   OR
       
   690                   (v_reversalinvoice_id IS NOT NULL AND c_invoice_id = v_reversalinvoice_id));
       
   691 
       
   692     END;
       
   693   END IF;
       
   694 
       
   695   --update em_aprm_processinvoice column with docaction value
       
   696   UPDATE c_invoice
       
   697   SET em_aprm_processinvoice = docaction
       
   698   WHERE c_invoice_id = p_record_id;
       
   699 
       
   700 EXCEPTION
       
   701 WHEN OTHERS THEN
       
   702   DBMS_OUTPUT.PUT_LINE('APRM_GENERATE_PAYMENT_SCHEDULE exception: '|| v_ResultStr);
       
   703   RAISE;
       
   704 END APRM_GEN_PAYMENTSCHEDULE_INV
       
   705 ]]></body>
       
   706     </function>
       
   707   </database>