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