modules/org.openbravo.advpaymentmngt/src-db/database/model/functions/APRM_TAX_PAYMENT.xml
changeset 9076 c4f1a5c7d7c2
child 15548 2232348ae463
equal deleted inserted replaced
9075:b3ea04de2722 9076:c4f1a5c7d7c2
       
     1 <?xml version="1.0"?>
       
     2   <database name="FUNCTION APRM_TAX_PAYMENT">
       
     3     <function name="APRM_TAX_PAYMENT" 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_record_id VARCHAR(60);
       
    25 p_user VARCHAR2(32);
       
    26 p_GLItem VARCHAR2(32);
       
    27 p_Amount NUMBER;
       
    28 p_IsReceipt CHAR(1);
       
    29 p_message VARCHAR(2000);
       
    30 p_result NUMBER;
       
    31 
       
    32 v_ResultStr VARCHAR2(2000):='';
       
    33 v_FIN_PAYMENT_ID FIN_PAYMENT.FIN_PAYMENT_ID%TYPE;
       
    34 v_PaymentDocType_ID FIN_PAYMENT.C_DOCTYPE_ID%TYPE;
       
    35 v_PaymentDocumentNo FIN_PAYMENT.DOCUMENTNO%TYPE;
       
    36 v_Financial_Account_ID FIN_FINANCIAL_ACCOUNT.FIN_FINANCIAL_ACCOUNT_ID%TYPE;
       
    37 v_PaymentMethod_ID C_INVOICE.FIN_PAYMENTMETHOD_ID%TYPE;
       
    38 v_CreateFinTransaction CHAR(1):='N';
       
    39 v_ExecutionType FIN_FINACC_PAYMENTMETHOD.PAYIN_EXECUTION_TYPE%TYPE;
       
    40 v_FIN_PAYMENT_DETAIL_ID FIN_PAYMENT_DETAIL.FIN_PAYMENT_DETAIL_ID%TYPE;
       
    41 v_FIN_FINACC_TRANSACTION_ID FIN_FINACC_TRANSACTION.FIN_FINACC_TRANSACTION_ID%TYPE;
       
    42 v_Line FIN_FINACC_TRANSACTION.LINE%TYPE;
       
    43 v_date DATE;
       
    44 v_Client_ID VARCHAR2(32);
       
    45 v_Org_ID VARCHAR2(32);
       
    46 v_Currency_id VARCHAR2(32);
       
    47 v_IsPayment CHAR(1);
       
    48 v_BPartner_ID VARCHAR2(32);
       
    49 v_Processed CHAR(1);
       
    50 v_Posted CHAR(1);
       
    51 v_Count NUMBER;
       
    52 
       
    53 TYPE RECORD IS REF CURSOR;
       
    54 Cur_Params RECORD;
       
    55 
       
    56 BEGIN
       
    57 
       
    58   FOR Cur_Params IN (
       
    59     SELECT *
       
    60     FROM ad_ep_instance_para
       
    61     WHERE ad_ep_instance_id = p_ep_instance
       
    62     ) LOOP
       
    63     IF (cur_params.parametername LIKE 'Record_ID') THEN
       
    64       p_record_id := cur_params.p_string;
       
    65     ELSIF (cur_params.parametername LIKE 'User') THEN
       
    66       p_user := cur_params.p_string;
       
    67     ELSIF (cur_params.parametername LIKE 'GLItem') THEN
       
    68       p_GLItem := cur_params.p_string;
       
    69     ELSIF (cur_params.parametername LIKE 'Amount') THEN
       
    70       p_amount := cur_params.p_number;
       
    71     ELSIF (cur_params.parametername LIKE 'IsReceipt') THEN
       
    72       p_isReceipt := cur_params.p_string;
       
    73     ELSIF (cur_params.parametername LIKE 'Message') THEN
       
    74       p_message := cur_params.p_text;
       
    75     ELSIF (cur_params.parametername LIKE 'Result') THEN
       
    76       p_result := cur_params.p_number;
       
    77     END IF;
       
    78   END LOOP;
       
    79 
       
    80   -- Reading the TAX PAYMENT
       
    81   v_ResultStr:='ReadingTaxPayment';
       
    82 
       
    83   select dateto, ad_client_id, ad_org_id, generatepayment, C_BPARTNER_ID, processed, FIN_PAYMENT_ID, C_Currency_ID
       
    84   into v_date, v_client_id, v_org_id, v_ispayment, v_bpartner_id, v_processed, v_FIN_PAYMENT_ID, v_Currency_id
       
    85   from c_taxpayment
       
    86   where c_taxpayment_id=p_record_id;
       
    87   
       
    88   IF (v_ispayment = 'Y' AND v_processed = 'N') THEN
       
    89     v_ResultStr:='Generating FIN_PAYMENT';
       
    90     v_FIN_PAYMENT_ID := GET_UUID();
       
    91     v_PaymentDocType_ID := AD_GET_DOCTYPE(v_client_id, v_org_id, CASE WHEN p_isreceipt='Y' THEN 'ARR' ELSE 'APP' END);
       
    92     AD_SEQUENCE_DOCTYPE(v_PaymentDocType_ID, v_client_id, 'Y', v_PaymentDocumentNo);
       
    93     IF (v_PaymentDocumentNo IS NULL) THEN
       
    94       AD_SEQUENCE_DOC('DocumentNo_FIN_Payment', v_client_id, 'Y', v_PaymentDocumentNo);
       
    95     END IF;
       
    96     select case when p_isreceipt='Y' then FIN_Financial_Account_id else PO_Financial_Account_id end, 
       
    97     case when p_isreceipt='Y' then fin_paymentmethod_id else po_paymentmethod_id end
       
    98     into v_Financial_Account_ID, v_PaymentMethod_ID
       
    99     from c_bpartner
       
   100     where c_bpartner_id = v_bpartner_id;
       
   101     SELECT CASE WHEN p_isreceipt='Y' THEN AUTOMATIC_DEPOSIT ELSE AUTOMATIC_WITHDRAWN END AS CreateFinTransaction,
       
   102     CASE WHEN p_isreceipt='Y' THEN payin_execution_type ELSE payout_execution_type END AS ExecutionType
       
   103     INTO v_CreateFinTransaction, v_ExecutionType
       
   104     FROM FIN_FINACC_PAYMENTMETHOD
       
   105     WHERE FIN_FINACC_PAYMENTMETHOD.FIN_PAYMENTMETHOD_ID = v_PaymentMethod_ID
       
   106     AND FIN_FINACC_PAYMENTMETHOD.FIN_FINANCIAL_ACCOUNT_ID = v_Financial_Account_ID
       
   107     AND FIN_FINACC_PAYMENTMETHOD.ISACTIVE='Y';
       
   108     -- Checking Payment Method ID is available
       
   109     IF(v_PaymentMethod_ID IS NULL) THEN
       
   110       RAISE_APPLICATION_ERROR(-20000, '@APRM_PAYMENTMETHOD_MISSING@');
       
   111     END IF;
       
   112     INSERT INTO fin_payment(
       
   113       fin_payment_id, ad_client_id, ad_org_id, created, createdby, 
       
   114       updated, updatedby, isactive, isreceipt, c_bpartner_id, paymentdate, 
       
   115       c_currency_id, amount, writeoffamt, fin_paymentmethod_id, documentno, 
       
   116       referenceno,
       
   117       status,
       
   118       processed, processing, posted, description, 
       
   119       fin_financial_account_id, c_doctype_id, c_project_id, c_campaign_id, 
       
   120       c_activity_id, user1_id, user2_id, em_aprm_process_payment, em_aprm_reconcile_payment, 
       
   121       em_aprm_add_scheduledpayments)
       
   122     VALUES (v_FIN_PAYMENT_ID, v_client_id, v_org_id, now(), p_user, 
       
   123       now(), p_user, 'Y', p_isreceipt, v_bpartner_id, v_date, 
       
   124       v_currency_id, p_amount, 0, v_PaymentMethod_ID, v_PaymentDocumentNo, 
       
   125       '',
       
   126       CASE 
       
   127 	WHEN v_ExecutionType = 'A' THEN 'RPAE' 
       
   128 	WHEN p_isreceipt = 'Y' THEN 'RPR'
       
   129 	ELSE 'PPM'
       
   130       END,
       
   131       'N', 'N', 'N', 'GL Item.: ', 
       
   132       v_Financial_Account_ID, v_PaymentDocType_ID, NULL, NULL, 
       
   133       NULL, NULL, NULL, 'N', 'N', 'N');
       
   134     v_FIN_PAYMENT_DETAIL_ID := GET_UUID();
       
   135     INSERT INTO fin_payment_detail(
       
   136       fin_payment_detail_id, ad_client_id, ad_org_id, created, createdby, 
       
   137       updated, updatedby, fin_payment_id, amount, refund, isactive, 
       
   138       writeoffamt, c_glitem_id, isprepayment)
       
   139 	VALUES (v_FIN_PAYMENT_DETAIL_ID, v_client_id, v_org_id, now(), p_user,
       
   140       now(), p_user, v_FIN_PAYMENT_ID, p_amount, 'N', 'Y', 
       
   141       0, p_GLItem, 'N');
       
   142     INSERT INTO fin_payment_scheduledetail(
       
   143     fin_payment_scheduledetail_id, ad_client_id, ad_org_id, created, createdby, 
       
   144     updated, updatedby, fin_payment_detail_id, fin_payment_schedule_order, 
       
   145     fin_payment_schedule_invoice, amount, isactive, writeoffamt)
       
   146     VALUES (GET_UUID(), v_client_id, v_org_id, now(), p_user, 
       
   147     now(), p_user, v_FIN_PAYMENT_DETAIL_ID, NULL, 
       
   148     NULL, p_amount, 'Y', 0);
       
   149     UPDATE FIN_PAYMENT SET PROCESSED = 'Y', EM_APRM_PROCESS_PAYMENT = 'R'
       
   150       WHERE FIN_PAYMENT_ID = v_FIN_PAYMENT_ID; 
       
   151     UPDATE C_TAXPAYMENT SET FIN_PAYMENT_ID = v_FIN_PAYMENT_ID
       
   152     WHERE C_TAXPAYMENT_ID = p_record_id;
       
   153     -- Updating SO_CREDITUSED when PAYMENT OCCUR
       
   154     UPDATE C_BPARTNER
       
   155     SET SO_CREDITUSED = SO_CREDITUSED - COALESCE(p_amount, 0)
       
   156     WHERE C_BPARTNER_ID = v_BPartner_ID; 
       
   157 
       
   158     -- Automatic creation of financial transaction
       
   159     IF(v_CreateFinTransaction = 'Y' AND v_ExecutionType = 'M') THEN
       
   160       v_ResultStr:='Generating FIN_FINACC_TRANSACTION';
       
   161       v_FIN_FINACC_TRANSACTION_ID := GET_UUID();
       
   162       SELECT COALESCE(MAX(LINE),0) INTO v_Line FROM FIN_FINACC_TRANSACTION WHERE FIN_FINANCIAL_ACCOUNT_ID = v_Financial_Account_ID;
       
   163       INSERT INTO fin_finacc_transaction(
       
   164 	fin_finacc_transaction_id, ad_client_id, ad_org_id, created, 
       
   165 	createdby, updated, updatedby, isactive, c_currency_id, fin_financial_account_id, 
       
   166 	line, fin_payment_id, dateacct, c_glitem_id, status, paymentamt, 
       
   167 	depositamt, processed, processing, posted, c_project_id, c_campaign_id, 
       
   168 	c_activity_id, user1_id, user2_id, trxtype, statementdate, description, 
       
   169 	fin_reconciliation_id)
       
   170       VALUES (v_FIN_FINACC_TRANSACTION_ID, v_client_id, v_org_id, now(), p_user,
       
   171 	now(), p_user, 'Y', v_currency_id, v_Financial_Account_ID, 
       
   172 	v_Line, v_FIN_PAYMENT_ID, v_date, NULL, CASE WHEN p_isreceipt='Y' THEN 'RDNC' ELSE 'PWNC' END, CASE WHEN p_isreceipt='N' THEN p_amount ELSE 0 END, 
       
   173 	CASE WHEN p_isreceipt='Y' THEN p_amount ELSE 0 END, 'Y', 'N', 'N', NULL, NULL, 
       
   174 	NULL, NULL, NULL, CASE WHEN p_isreceipt='N' THEN 'BPW' ELSE 'BPD' END, v_date, 'GL Item: ' , 
       
   175 	NULL);
       
   176       UPDATE FIN_PAYMENT SET STATUS = CASE WHEN p_isreceipt='Y' THEN 'RDNC' ELSE 'PWNC' END
       
   177 	WHERE FIN_PAYMENT_ID = v_FIN_PAYMENT_ID;
       
   178 	--UPDATE FINANCIAL ACCOUNT CURRENT BALANCE
       
   179 	UPDATE FIN_FINANCIAL_ACCOUNT SET CURRENTBALANCE=CURRENTBALANCE + (CASE WHEN p_isreceipt='Y' THEN p_amount ELSE (p_amount*-1) END)
       
   180 	WHERE FIN_FINANCIAL_ACCOUNT_ID = v_Financial_Account_ID;
       
   181     END IF;
       
   182   ELSIF (v_ispayment = 'Y' AND v_Processed = 'Y') THEN
       
   183     select posted into v_posted from FIN_PAYMENT where FIN_PAYMENT_ID = v_FIN_PAYMENT_ID;
       
   184     if v_posted = 'Y' then
       
   185       RAISE_APPLICATION_ERROR(-20000, '@PaymentDocumentPosted@') ;
       
   186     end if;
       
   187     select count(*) INTO v_Count
       
   188     from fin_finacc_transaction
       
   189     where fin_payment_id = v_FIN_PAYMENT_ID;
       
   190     if v_Count>0 then
       
   191       RAISE_APPLICATION_ERROR(-20000, '@APRM_TransactionExists@') ;
       
   192     end if;
       
   193     UPDATE FIN_PAYMENT SET PROCESSED = 'N' WHERE FIN_PAYMENT_ID = v_FIN_PAYMENT_ID;
       
   194     UPDATE C_TAXPAYMENT SET FIN_PAYMENT_ID = NULL WHERE C_TAXPAYMENT_ID = p_record_id;
       
   195     DELETE FROM FIN_PAYMENT_SCHEDULEDETAIL WHERE EXISTS (SELECT 1 FROM FIN_PAYMENT_DETAIL WHERE FIN_PAYMENT_ID = v_FIN_PAYMENT_ID
       
   196 	AND FIN_PAYMENT_SCHEDULEDETAIL.FIN_PAYMENT_DETAIL_ID = FIN_PAYMENT_DETAIL.FIN_PAYMENT_DETAIL_ID);
       
   197     DELETE FROM FIN_PAYMENT_DETAIL WHERE FIN_PAYMENT_ID = v_FIN_PAYMENT_ID;
       
   198     DELETE FROM FIN_PAYMENT WHERE FIN_PAYMENT_ID = v_FIN_PAYMENT_ID;
       
   199   END IF;
       
   200 
       
   201 EXCEPTION
       
   202 WHEN OTHERS THEN
       
   203   DBMS_OUTPUT.PUT_LINE('APRM_TAX_PAYMENT exception: '|| v_ResultStr);
       
   204   RAISE;
       
   205 END APRM_TAX_PAYMENT
       
   206 ]]></body>
       
   207     </function>
       
   208   </database>