During a Sales Order Creation scenario, when data is inserted into Interface table – sometimes Orders can fail to get created due to issues in the Interface table. The corresponding error information is stored in the oe_processing_msgs_tl table.
The query to find out error messages in the Order Interface table is:
SELECT *
FROM oe_processing_msgs opm,
oe_processing_msgs_tl opmt
WHERE opm.transaction_id = opmt.transaction_id
AND opm.original_sys_document_ref = '123456';
--- where 123456 is the Order Number in the interface table.
--- Interface table information.
SELECT *
FROM oe_headers_iface_all
WHERE order_number = '123456';
SELECT *
FROM oe_lines_iface_all
WHERE orig_sys_document_ref = (SELECT orig_sys_document_ref
FROM oe_headers_iface_all
WHERE order_number = '123456');
During the Payables Invoice Interface process, one of the validations involve validating the Vendor Number for which the Invoice is being created for. The Validation logic checks in the system to see if a vendor already exists for that vendor number. If Yes, then an Invoice can be created for that Supplier. Else, since that Supplier doesn’t exist, Invoices cannot be created against that supplier and the validation should result in error.
DECLARE
p_vendor_num ap_suppliers.segment1%TYPE;
l_vendor_id ap_suppliers.vendor_id%TYPE;
CURSOR cur_vendor_num_chk (cp_vendor_num ap_suppliers.segment1%TYPE)
IS
SELECT vendor_id
FROM ap_suppliers
WHERE segment1 = cp_vendor_num;
BEGIN
OPEN cur_vendor_num_chk (p_vendor_num);
FETCH cur_vendor_num_chk INTO l_vendor_id;
IF (cur_vendor_num_chk%FOUND)
THEN
DBMS_OUTPUT.put_line (
'Supplier exists in the system '
|| CHR (10)
|| ' Thus, Invoice Can be created for this vendor.');
ELSE
DBMS_OUTPUT.put_line (
'Supplier does not exist and Invoice cannot be created using this Supplier');
END IF;
CLOSE cur_vendor_num_chk;
EXCEPTION
WHEN OTHERS
THEN
DBMS_OUTPUT.put_line ('Error while validation: ' || SQLERRM);
END;
During the Payables Invoice Interface process, one of the validations involve validating the Invoice Number. If the Invoice Number already exists in the system for a given Vendor in a given Operating Unit, then another Invoice cannot be created with the same Invoice Number. The following logic can be used for validation:
DECLARE
p_inv_number ap_invoices_all.invoice_num%TYPE;
p_vendor_id ap_invoices_all.vendor_id%TYPE;
p_org_id ap_invoices_all.org_id%TYPE;
l_inv_id ap_invoices_all.invoice_id%TYPE;
CURSOR cur_inv_num_chk (
cp_inv_number ap_invoices_all.invoice_num%TYPE,
cp_vendor_id ap_invoices_all.vendor_id%TYPE,
cp_org_id ap_invoices_all.org_id%TYPE)
IS
SELECT invoice_id
FROM ap_invoices_all
WHERE invoice_number = cp_inv_number
AND vendor_id = cp_vendor_id
AND org_id = cp_org_id;
BEGIN
OPEN cur_inv_num_chk (p_inv_number, p_vendor_id, p_org_id);
FETCH cur_inv_num_chk INTO l_inv_id;
IF (cur_inv_num_chk%FOUND)
THEN
DBMS_OUTPUT.put_line (
'Invoice already exists in the system'
|| CHR (10)
|| ' Thus, Invoice Cannot be created with this Invoice Number
for this Vendor '
|| p_vendor_id
|| ' in this organization: '
|| p_org_id);
ELSE
DBMS_OUTPUT.put_line (
'Invoice does not exist and can be created using this Invoice Number');
END IF;
CLOSE cur_inv_num_chk;
EXCEPTION
WHEN OTHERS
THEN
DBMS_OUTPUT.put_line ('Error while validation: ' || SQLERRM);
END;
Objective: The primary objective of this post is to understand why and how to import data into Oracle Applications in order to create Payables Invoices.
As one can understand the difference between a conversion process and an Interface – A conversion process is conducted once during a cycle to import legacy data into the Oracle, whereas an Interface is used on a daily basis to import external data into Oracle.
Many a times, users are given the task of importing external data into Oracle and create AP Invoices. Invoice data comes from sources including:
EDI invoices from your suppliers that you load through Oracle e-Commerce Gateway.
Supplier invoices that you transfer through the Oracle XML Gateway.
Invoices that you load using Oracle SQL*Loader lease invoices from Oracle Property Manager.
Lease payments from Oracle Assets, credit card transaction data that you load using the Credit Card Invoice Interface Summary.
Invoices that you enter through the Invoice Gateway.
An Interface process goes through the following stages. A brief overview of the process is as below.
Invoice_Interface_Process
Step1: Loading into Staging table
Also, the inbound data can be loaded into the staging table in either of the following ways:
Interfaced into the staging table using middleware technologies like webmethods or SOA.
The data can be created and placed in a csv file and can be loaded into the staging table using SQL Loader. (Please check my sql loader tutorial for understanding this process).
Usually the data and the staging tables are designed in such a way that one row in the staging table has all the header and Line Information associated with the Payables Invoice. Also, the staging table is designed in such a way that it mimics the columns in the AP Invoice Header and Line tables. (AP_INVOICES_ALL and AP_INVOICE_LINES_ALL) tables.
Step 2: Validating Staging table
Once, the data is placed in the staging table, the data here goes through validation. Some of the basic validations that are required for AP Invoice Interface are:
And depending on the data / columns in the staging table – more validations may be required based on the current requirement.
During the validation process, each record in the staging table is marked either as a Processed record or a failed record, depending on whether the record passed validation or not.
If the record fails validation, then the corresponding process_flag (or whatever the name of the column that you give) column in the staging table is marked as E (error). Else, if the record passes validation, then the process_flag for that record is marked as V (Validated)
Step 3: Loading into Interface Table.
All the records from the staging table that has the process_flag as ‘V‘ are then inserted into the Interface tables.
All the Header information from the staging table is passed to AP_Invoices_Interface table and all the Line Information is passed to AP_Invoice_lines_interface table.
Some of the important columns that have to be populated in the Interface tables are:
AP_INVOICES_INTERFACE:
INVOICE_ID
Invoice identifier. Must be unique.
INVOICE_NUM
Supplier invoice number. Validation: must be unique for the supplier site.
INVOICE_TYPE_LOOKUP_CODE
Type of invoice. Use the Manage Payables Lookups task, lookup type INVOICE TYPE to identify valid values.
INVOICE_DATE
Invoice date used to calculate due date per payment terms. Date format: YYYY/MM/DD.
PO_NUMBER
Document number used to request a seller supply a product or service for payment. Use the Manage Purchase Orders task to identify valid values.
VENDOR_ID
Supplier identifier. If the identifier is not available, use the VENDOR_NAME column. Validated against POZ_SUPPLIERS.VENDOR_ID.
VENDOR_NUM
Unique number to identify a supplier. Use the Manage Suppliers task to identify valid values.
VENDOR_NAME
Supplier name. Use the Manage Suppliers task to identify valid values.
VENDOR_SITE_ID
Supplier site identifier. If the identifier is not available, use the VENDOR_SITE_CODE column. Validated against POZ_SUPPLIER_SITES_ALL.VENDOR_SITE_ID.
VENDOR_SITE_CODE
Physical location of the supplier. Use the Manage Suppliers task to identify valid values.
INVOICE_AMOUNT
Invoice amount in transaction currency. Should be positive for standard and prepayment invoices. Should be negative for credit memos.
INVOICE_CURRENCY_CODE
Currency of invoice. Use the Manage Currencies task to identify valid values. Use the three character ISO currency code. Example: US Dollars is USD.
EXCHANGE_RATE
Exchange rate used for foreign currency invoices. User entered conversion rate. Not validated.
EXCHANGE_RATE_TYPE
Exchange rate type for foreign currency invoices. Use the Manage Conversion Rate Types task to identify valid values. Validated against GL_DAILY_CONVERSION_TYPES.CONVERSION_TYPE.
EXCHANGE_DATE
Date exchange rate is effective. Usually the accounting date of the transaction. Date format: YYYY/MM/DD.
TERMS_ID
Payment terms identifier. If the identifier is not available, use the TERMS_NAME column. Validated against AP_TERMS_TL.TERM_ID.
TERMS_NAME
Name of payment term for an invoice. Use the Manage Payment Terms task to identify valid values.
DESCRIPTION
Invoice description. Free text field. Not validated.
AP_INVOICE_LINES_INTERFACE:
INVOICE_ID
Invoice identifier. Must be unique.
INVOICE_LINE_ID
Unique number for each invoice line of an invoice. If NULL, populated by AP_INVOICE_LINES_INTERFACE_S sequence.
LINE_NUMBER
Invoice line number. Must be a positive integer. Must be unique per invoice.
LINE_TYPE_LOOKUP_CODE
Type of invoice line. Use the Manage Payables Lookups task, lookup type INVOICE LINE TYPE to identify valid values.
LINE_GROUP_NUMBER
Line group number. Used to prorate charges across a group of lines. Must be a positive integer.
AMOUNT
Amount of the invoice line. Validated against the invoice type. Example: standard invoices must have positive amounts. Amount precision is validated against the currency.
ACCOUNTING_DATE
Date when the invoice line is to be accounted. Date format: YYYY/MM/DD.
DESCRIPTION
Description of the invoice line. Free text field. Not validated.
Step 4: Submit Standard Program.
Once the data is inserted into the Interface table, submit the “Payables Open Interface Import” standard import program to import the Interface data and create the Payables Invoices.
When data is being migrated from Interface tables to the base tables in the above step – some of the data in the Interface tables may get into error and will not be used to create the Invoices. These records can be found in the AP_INTERFACE_REJECTIONS table.
The join between the AP_Interface_Rejections and the two Interface tables is:
select air.reject_lookup_code, air.*
from ap_interface_rejections air
,ap_invoices_interface ait
where air.parent_id = ait.invoice_id
and air.parent_table = 'AP_INVOICES_INTERFACE'
select air.reject_lookup_code, air.*
from ap_interface_rejections air
,ap_invoice_lines_interface ail
where air.parent_id = ail.invoice_line_id
and air.parent_table = 'AP_INVOICE_LINES_INTERFACE'
Step 6: Verify the created Invoices
Login into Oracle Applications and navigate to Payables Superuser to query the created Invoices from the front end application and in the following base tables:
select * from ap_invoices_all
select * from ap_invoice_lines_all
While inserting Item related data into the MTL_SYSTEM_ITEMS_INTERFACE interface table, we need to validate the Unit of Measure field. In order to validate the Unit of Measure (UOM) already exists in the system, check if the UOM exists in the MTL_UNITS_OF_MEASURE table.
DECLARE
l_unit_of_measure mtl_units_of_measure.unit_of_measure%TYPE;
p_uom_code mtl_units_of_measure.uom_code%TYPE;
BEGIN
p_uom_code := 'EA';
SELECT unit_of_measure
INTO l_unit_of_measure
FROM mtl_units_of_measure
WHERE uom_code = p_uom_code;
DBMS_OUTPUT.put_line ('Unit of Measure is: ' || l_unit_of_measure);
EXCEPTION
WHEN OTHERS
THEN
DBMS_OUTPUT.put_line ('Unit of Measure does not exist: ' || SQLERRM);
END;