, , ,

How to Insert Attachments in R12 Using API

This article explains how to insert attachments using Oracle API’s from Back end. Working on attachments need some knowledge of how an attachment functions (Definitions, Entity, Document Category, Entities and Blocks, Primary Keys in attachments) in Oracle Apps. To understand the below API and what it actually does its advisable to read the Attachments Chapter in Developers Guide.

https://docs.oracle.com/cd/E26401_01/doc.122/e22961/T302934T462356.htm

Primary Key information that uniquely identifies the product (such as the INVOICE_ID).

Below API takes single file from a shared drive and inserts into fnd_lobs. Then it’s attached to a particular Id (like check_id, invoice_id..) using the combination of pk1_value, entity name and category.

This sample shows how an attachment API works. You can use it to customize/enhance to requirement.

//Tested in R12.1.3

–Create a Server Directories in Oracle
–This will be done by DBA mostly
–Physical directory must be created inorder to save the files into server
CREATE OR REPLACE DIRECTORY SALE_INVOICE_PATH AS ‘/files/SALE_INVOICE/’;

SET SERVEROUTPUT ON;
DECLARE
l_rowid ROWID;
l_attached_document_id NUMBER;
l_document_id NUMBER;
l_media_id NUMBER;
l_category_id number;
l_pk1_value fnd_attached_documents.pk1_value%type:= 999999; –Primary Key information that uniquely identifies the information
l_description fnd_documents_tl.description%type:= ‘Customer Invoice Attachment’;
l_filename VARCHAR2(240) := ‘Sales_Invoice_14Nov2016.pdf’;
l_file_path varchar2(240) := ‘SALE_INVOICE_PATH’; –Server Directory Path for upload files
l_seq_num NUMBER;
l_blob_data BLOB;
l_blob BLOB;
l_bfile BFILE;
l_byte NUMBER;
l_fnd_user_id NUMBER;
l_short_datatype_id NUMBER;
x_blob BLOB;
fils BFILE;
blob_length integer;
l_entity_name varchar2(100) := ‘CUSTOM_LOAD’; –Must be defined before or use existing ones. Table: FND_DOCUMENT_ENTITIES
l_category_name VARCHAR2(100) := ‘Other’; –Must be defined before or use existing ones.

BEGIN
–Enter USER_ID,RESP_ID,RESP_APPL_ID
fnd_global.apps_initialize (&USER_ID, &RESP_ID, &RESP_APPL_ID);

SELECT fnd_documents_s.NEXTVAL
INTO l_document_id
FROM DUAL;

SELECT fnd_attached_documents_s.NEXTVAL
INTO l_attached_document_id
FROM DUAL;

SELECT NVL (MAX (seq_num), 0) + 10
INTO l_seq_num
FROM fnd_attached_documents
WHERE pk1_value = l_pk1_value AND entity_name = l_entity_name;

— Select User_id
SELECT user_id
INTO l_fnd_user_id
from apps.fnd_user
WHERE user_name = ‘OPERATIONS’; –Username who will be uploading file.

— Get Data type id for Short Text types of attachments
SELECT datatype_id
INTO l_short_datatype_id
FROM apps.fnd_document_datatypes
WHERE NAME = ‘FILE’;

— Select Category id for Attachments
SELECT category_id
INTO l_category_id
FROM apps.fnd_document_categories_vl
WHERE USER_NAME = l_category_name;

— Select nexvalues of document id, attached document id and
SELECT apps.fnd_documents_s.NEXTVAL,
apps.fnd_attached_documents_s.NEXTVAL
into l_document_id,l_attached_document_id
FROM DUAL;

SELECT fnd_lobs_s.nextval
INTO l_media_id
FROM dual;

fils := BFILENAME (l_file_path, l_filename);

— Obtain the size of the blob file
DBMS_LOB.fileopen (fils, DBMS_LOB.file_readonly);
blob_length := DBMS_LOB.getlength (fils);
DBMS_LOB.fileclose (fils);

— Insert a new record into the table containing the
— filename you have specified and a LOB LOCATOR.
— Return the LOB LOCATOR and assign it to x_blob.

INSERT INTO fnd_lobs
(file_id, file_name, file_content_type, upload_date,
expiration_date, program_name, program_tag, file_data,
LANGUAGE, oracle_charset, file_format
)
VALUES (l_media_id, l_filename, ‘application/pdf’,–‘text/plain’,
SYSDATE, NULL, ‘FNDATTCH’, NULL, EMPTY_BLOB (), –l_blob_data,
‘US’, ‘UTF8’, ‘binary’
)
RETURNING file_data
INTO x_blob;

— Load the file into the database as a BLOB
DBMS_LOB.OPEN (fils, DBMS_LOB.lob_readonly);
DBMS_LOB.OPEN (x_blob, DBMS_LOB.lob_readwrite);
DBMS_LOB.loadfromfile (x_blob, fils, blob_length);

— Close handles to blob and file
DBMS_LOB.CLOSE (x_blob);
DBMS_LOB.CLOSE (fils);

DBMS_OUTPUT.put_line (‘FND_LOBS File Id Created is ‘ || l_media_id);

COMMIT;

— This package allows user to share file across multiple orgs or restrict to single org

fnd_documents_pkg.insert_row
(x_rowid => l_rowid,
x_document_id => l_document_id,
x_creation_date => SYSDATE,
x_created_by => l_fnd_user_id,
x_last_update_date => SYSDATE,
x_last_updated_by => l_fnd_user_id,
x_last_update_login => fnd_profile.VALUE(‘LOGIN_ID’),
x_datatype_id => l_short_datatype_id,
X_security_id => 21, –Security ID defined in your Attchments, Usaully SOB ID/ORG_ID
x_publish_flag => ‘N’, –This flag allow the file to share across multiple organization
x_category_id => l_category_id,
x_security_type => 1,
x_usage_type => ‘S’,
x_language => ‘US’,
x_description => l_description,
x_file_name => l_filename,
x_media_id => l_media_id
);

commit;

— Description informations will be stored in below table based on languages.
fnd_documents_pkg.insert_tl_row
(x_document_id => l_document_id,
x_creation_date => SYSDATE,
x_created_by => l_fnd_user_id,
x_last_update_date => SYSDATE,
x_last_updated_by => l_fnd_user_id,
x_last_update_login => fnd_profile.VALUE(‘LOGIN_ID’),
x_language => ‘US’,
x_description => l_description
);
commit;

fnd_attached_documents_pkg.insert_row
(x_rowid => l_rowid,
x_attached_document_id => l_attached_document_id,
x_document_id => l_document_id,
x_creation_date => SYSDATE,
x_created_by => l_fnd_user_id,
x_last_update_date => SYSDATE,
x_last_updated_by => l_fnd_user_id,
x_last_update_login => fnd_profile.VALUE(‘LOGIN_ID’),
x_seq_num => l_seq_num,
x_entity_name => l_entity_name,
x_column1 => NULL,
x_pk1_value => l_pk1_value,
x_pk2_value => NULL,
x_pk3_value => NULL,
x_pk4_value => NULL,
x_pk5_value => NULL,
x_automatically_added_flag => ‘N’,
x_datatype_id => 6,
x_category_id => l_category_id,
x_security_type => 1,
X_security_id => 21, –Security ID defined in your Attchments, Usaully SOB ID/ORG_ID
x_publish_flag => ‘Y’,
x_language => ‘US’,
x_description => l_description,
x_file_name => l_filename,
x_media_id => l_media_id
);
COMMIT;
DBMS_OUTPUT.put_line (‘MEDIA ID CREATED IS ‘ || l_media_id);
end;
/

Learn more on Attachments on this article.

4 replies
  1. Enno Pommerening
    Enno Pommerening says:

    You must use

    select fnd_lobs_s.nextval into l_media_id from dual;

    instead of:

    SELECT MAX (file_id) + 1
    INTO l_media_id
    FROM fnd_lobs;
    (otherwise other programs may file with unique constraint error .. )

    Reply
  2. THOMSON ALEXANDER
    THOMSON ALEXANDER says:

    In the example above we are accessing a file from oracle directory. What if I need to upload file from my PC . Should we still need to upload to directory first before loading to fnd_lobs

    Reply
  3. Aijaz Rahman
    Aijaz Rahman says:

    Hello,

    I have a similar requirement, we are developing a Mobile App for Employee Self Services, we need to allow the users to upload documents from mobile devices. When I checked the code by developers, they are using a direct insert on FND_LOBS table which I did not approve. Developers says, there is no Standard API for FND_LOBS that’s why they want to insert directly.

    My concern is, Firstly of all, it’s not recommended to allow a direct insert on any table from a 3rd party product. Specially from a mobile device (Public device) which is more vulnerable to viruses then the organization network.

    Secondly, if we allow direct insert on FND_LOBS it will trigger performance issues by generating db level locks and sessions getting hanged and then over all performance degradation.

    Kindly suggest what should be the best approach to meet this business requirement ?

    Reply

Leave a Reply

Want to join the discussion?
Feel free to contribute!

Leave a Reply