Wednesday, February 14, 2018

Oracle Apps: Helpful Queries on FND Attachments tables and sample code to extract attachments

Oracle Apps: Helpful Queries on FND Attachments tables and sample code to extract attachments

This post gives some helpful queries when working on FND Attachment tables. I have also given a sample program to extract these attachment into file system.

Attachment Types are stored in the fnd_document_datatypes table.


select * from fnd_document_datatypes;

Attachment in Oracle Application

What is attachment in oracle application?
The attachments feature in oracle application enables users to link unstructured data, such as images, word-processing documents, spreadsheets, or text to their application data. For example, users can link images to items or video to operations as operation instructions.
Where to find an attachment?
There is an attachment icon in the oracle application toolbar that indicates whether the Attachments feature is enabled in a form block. When the button is dimmed, the Attachment feature is not available. When the Attachment feature is enabled in a form block, the icon becomes a solid paper clip. The icon switches to a paper clip holding a paper when the Attachment feature is enabled in a form lock and the current record has at least one attachment.
Attachment types:
An attached document can be:
1] Short Text
Text stored in the database containing less than 2000 characters.
2] Long Text
Text stored in the database containing 2000 characters or more.
3] Image
An image that Oracle Forms can display, including: bmp, cals, jfif, jpeg, gif, pcd, pcx, pict, ras, and tif.
4] OLE Object
An OLE Object that requires other OLE server applications to view, such as Microsoft Word or Microsoft Excel.
5] Web Page
A URL reference to a web page which you can view with your web browser.
Tables Involved:
For Importing Attachments in oracle application one has to populate following tables.
1. FND_DOCUMENTS
2. FND_ATTACHED_DOCUMENTS
3. FND_DOCUMENTS_TL
4. FND_DOCUMENT_DATATYPES.
5. FND_DOCUMENT_CATEGORIES
6. FND_DOCUMENTS_LONG_TEXT (Long text type attachment).
7. FND_DOCUMENTS_SHORT_TEXT (Short text type attachment).
8. FND_DOCUMENTS_LONG_RAW
9. FND_LOBS (File type attachments).
FND_DOCUMENTS:
FND_DOCUMENTS stores language-independent information about a document. For example, each row contains a document identifier, a category identifier, the method of security used for the document (SECURITY_TYPE, where 1=Organization,2=Set of Books, 3=Business unit,4=None), the period in which the document is active, and a flag to indicate whether or not the document can be shared outside of the security type (PUBLISH_FLAG).
Other specifications in this table include: datatype (DATATYPE_ID, where 1=short text,2=long text, 3=image, 4=OLE object), image type, and storage type (STORAGE_TYPE, where 1=stored in the database, 2=stored in the file system).
The document can be referenced by many application entities and changed only in the define document form (USAGE_TYPE=S); it can be used as a fill-in-the-blanks document, where each time you use a template, you make a copy of it (USAGE_TYPE=T); or it can be used only one time (USAGE_TYPE=O).Images and OLE Objects cannot be used as templates.
FND_ATTACHED_DOCUMENTS:
FND_ATTACHED_DOCUMENTS stores information relating a document to an application entity.  For example, a record may link a document to a sales order or an item. Each row contains foreign keys to FND_DOCUMENTS and FND_DOCUMENT_ENTITIES. There is also a flag to indicate whether or not an attachment was created automatically.
FND_DOCUMENTS_TL:
FND_DOCUMENTS_TL stores translated information about the documents in FND_DOCUMENTS. Each row includes the document identifier, the language the row is translated to, the description of the document, the file in which the image is stored, and an identifier (MEDIA_ID) of the sub-table in which the document is saved (FND_DOCUMENTS_SHORT_TEXT, FND_DOCUMENTS_LONG_TEXT, or FND_DOCUMENTS_LONG_RAW).
FND_DOCUMENT_DATATYPES:
FND_DOCUMENT_DATATYPES stores the document datatypes that are supported. Initial values are: short text, long text, image, and OLE Object (DATATYPE_ID=1, 2, 3, or 4). Customers can add datatypes to handle documents stored outside of Oracle and use non-native Forms applications to view/edit their documents. The table uses a “duplicate record” model for handling multi-lingual needs. That is, for each category there will be one record with the same CATEGORY_ID and CATEGORY_NAME for each language.
FND_DOCUMENT_CATEGORIES:
FND_DOCUMENT_CATEGORIES stores information about the categories in which documents are classified. For example, documents may be considered “Bill of Material Comments”, “WIP Job Comments”, etc. Document categories are used to provide a measure of security on documents. Each form that enables the attachment feature lists which categories of documents can be viewed in the form. This table uses a “duplicate record” model for handling multi-lingual needs.
FND_DOCUMENTS_LONG_TEXT:
FND_DOCUMENTS_LONG_TEXT stores information about long text documents.
FND_DOCUMENTS_SHORT_TEXT:
FND_DOCUMENTS_SHORT_TEXT stores information about short text documents.
FND_DOCUMENTS_LONG_RAW:
FND_DOCUMENTS_LONG_RAW stores images and OLE Objects, such as Word Documents and Excel spreadsheets, in the database.
FND_DOCUMENT_ENTITIES:
FND_DOCUMENT_ENTITIES lists each entity to which attachments can be linked. For example, attachments can be linked to Items, Sales Orders, etc. Since the table uses a “duplicate record” model for handling multi-lingual needs, for each document entity there will be one record with the same DOCUMENT_ENTITY_ID and DATA_OBJECT_CODE for each language.
Queries:
1] To find all Long Text attachments:
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
SELECT
        FAD.SEQ_NUM "Seq Number",
        FDAT.USER_NAME "Data Type",
        FDCT.USER_NAME "Category User Name",
        FAD.ATTACHED_DOCUMENT_ID "Attached Document Id",
        FDET.USER_ENTITY_NAME "User Entity",
        FD.DOCUMENT_ID "Document Id",
        FAD.ENTITY_NAME "Entity Name",
        FD.MEDIA_ID "Media Id",
        FD.URL "Url",
        FDT.TITLE "Title",
        FDLT.LONG_TEXT "Attachment Text"
FROM
        FND_DOCUMENT_DATATYPES FDAT,
        FND_DOCUMENT_ENTITIES_TL FDET,
        FND_DOCUMENTS_TL FDT,
        FND_DOCUMENTS FD,
        FND_DOCUMENT_CATEGORIES_TL FDCT,
        FND_ATTACHED_DOCUMENTS   FAD,
        FND_DOCUMENTS_LONG_TEXT FDLT
WHERE
        FD.DOCUMENT_ID          = FAD.DOCUMENT_ID
        AND FDT.DOCUMENT_ID     = FD.DOCUMENT_ID
        AND FDCT.CATEGORY_ID    = FD.CATEGORY_ID
        AND FD.DATATYPE_ID      = FDAT.DATATYPE_ID
        AND FAD.ENTITY_NAME     = FDET.DATA_OBJECT_CODE
        AND FDLT.MEDIA_ID       = FD.MEDIA_ID
        AND FDAT.NAME           = 'LONG_TEXT';
2] To find all Short Text attachments:
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
SELECT
        FAD.SEQ_NUM "Seq Number",
        FDAT.USER_NAME "Data Type",
        FDCT.USER_NAME "Category User Name",
        FAD.ATTACHED_DOCUMENT_ID "Attached Document Id",
        FDET.USER_ENTITY_NAME "User Entity",
        FD.DOCUMENT_ID "Document Id",
        FAD.ENTITY_NAME "Entity Name",
        FD.MEDIA_ID "Media Id",
        FD.URL "Url",
        FDT.TITLE "Title",
        FDST.SHORT_TEXT "Attachment Text"
FROM
        FND_DOCUMENT_DATATYPES FDAT,
        FND_DOCUMENT_ENTITIES_TL FDET,
        FND_DOCUMENTS_TL FDT,
        FND_DOCUMENTS FD,
        FND_DOCUMENT_CATEGORIES_TL FDCT,
        FND_ATTACHED_DOCUMENTS   FAD,
        FND_DOCUMENTS_SHORT_TEXT FDST
WHERE
        FD.DOCUMENT_ID          = FAD.DOCUMENT_ID
        AND FDT.DOCUMENT_ID     = FD.DOCUMENT_ID
        AND FDCT.CATEGORY_ID    = FD.CATEGORY_ID
        AND FD.DATATYPE_ID      = FDAT.DATATYPE_ID
        AND FAD.ENTITY_NAME     = FDET.DATA_OBJECT_CODE
        AND FDST.MEDIA_ID       = FD.MEDIA_ID
        AND FDAT.NAME           = 'SHORT_TEXT';
Attachment upload through API:
Attachments can also be uploaded through an oracle provided API called  FND_ATTACHED_DOCUMENTS_PKG.
It consist of three procedures
1)  Insert Row
2)  Update Row
3)  Lock Row
Names of these procedures are self explanatory. insert row is used to insert a new row for attachment data, update row is used to update existing row for a particular row and Lock Row is used to lock a existing row for further modification.


Query to retrieve the 'Short Text' Attachments:
 select fad.document_id  
       ,fad.entity_name  
       ,fad.pk1_value  
       ,fad.pk2_value
       ,fdct.user_name "Category"
       ,fdd.user_name "Type"  
       ,fds.short_text  
       ,(fad.entity_name || '_' || fad.document_id ||'_ST.txt') file_name  
 from fnd_attached_documents fad  
     ,fnd_documents fd  
     ,fnd_documents_short_text fds
     ,fnd_document_datatypes fdd
     ,fnd_document_categories_tl fdct  
 where fad.document_id = fd.document_id  
 and   fd.media_id     = fds.media_id  
 and   fd.datatype_id  = fdd.datatype_id  
 and   fd.category_id  = fdct.category_id
 and   fdd.user_name   = 'Short Text'  
 and   fad.entity_name = :p_entity_name -- replace with the entity_name you want to extract.  
 order by fad.pk1_value, pk2_value;  

Query to retrieve the 'Long Text' Attachments:
 select fad.entity_name  
       ,fad.document_id  
       ,fad.pk1_value  
       ,fad.pk2_value
       ,fdct.user_name "Category"
       ,fdd.user_name "Type"  
       ,fdl.long_text  
       ,(fad.entity_name || '_' || fad.document_id ||'_LT.txt') file_name  
 from fnd_attached_documents fad  
     ,fnd_documents fd  
     ,fnd_documents_long_text fdl
     ,fnd_document_datatypes fdd
     ,fnd_document_categories_tl fdct    
 where fad.document_id = fd.document_id  
 and   fd.media_id     = fdl.media_id  
 and   fd.datatype_id  = fdd.datatype_id
 and   fd.category_id  = fdct.category_id  
 and   fdd.user_name   = 'Long Text'  
 and   fad.entity_name = :p_entity_name -- replace with the entity_name you want to extract.  
 order by fad.pk1_value, pk2_value;  

Query to retrieve the 'File' Attachments:
 select fad.entity_name   
       ,fad.document_id  
       ,fad.pk1_value  
       ,fad.pk2_value
       ,fdct.user_name "Category"
       ,fdd.user_name "Type"  
       ,fd.datatype_id  
       ,(fad.entity_name || '_' || fad.document_id ||'_' || fl.file_name) file_name  
       ,fl.file_data  
 from fnd_attached_documents fad  
     ,fnd_documents fd  
     ,fnd_lobs fl
     ,fnd_document_datatypes fdd
     ,fnd_document_categories_tl fdct    
 where fad.document_id = fd.document_id  
 and   fd.media_id     = fl.file_id  
 and   fd.datatype_id  = fdd.datatype_id
 and   fd.category_id  = fdct.category_id  
 and   fdd.user_name   = 'File'  
 and   fad.entity_name = :p_entity_name -- replace with the entity_name you want to extract.  
 order by fad.pk1_value, pk2_value;  

Query to retrieve the 'Web Page' Attachments:

 select fad.entity_name  
       ,fad.document_id  
       ,fad.pk1_value  
       ,fad.pk2_value
       ,fdct.user_name "Category"
       ,fdd.user_name "Type"  
       ,(fad.entity_name || '_' || fad.document_id ||'_URL.txt') file_name  
       ,fd.url  
 from fnd_attached_documents fad  
     ,fnd_documents fd
     ,fnd_document_datatypes fdd
     ,fnd_document_categories_tl fdct    
 where fad.document_id = fd.document_id  
 and   fd.datatype_id  = fdd.datatype_id
 and   fd.category_id  = fdct.category_id  
 and   fdd.user_name   = 'Web Page'  
 and   fad.entity_name = :p_entity_name -- replace with the entity_name you want to extract.  
 order by fad.pk1_value, pk2_value;  

Sample program to extract the attachments into file system.

declare  
  v_file     utl_file.file_type;   
  v_line     varchar2(1000);   
  v_blob_len number;  
  v_pos      number;  
  v_buffer   raw(32764);  
  v_amt      binary_integer := 32764;
  
  cursor cur_short_text_files  
  is  
    select fad.entity_name   
          ,fad.document_id   
          ,fad.pk1_value   
          ,fad.pk2_value   
          ,fds.short_text   
          ,(fad.entity_name || '_' || fad.document_id ||'_ST.txt') file_name   
    from fnd_attached_documents fad   
        ,fnd_documents fd   
        ,fnd_documents_short_text fds  
        ,fnd_document_datatypes fdd   
    where fad.document_id = fd.document_id   
    and   fd.media_id     = fds.media_id   
    and   fd.datatype_id  = fdd.datatype_id   
    and   fdd.user_name   = 'Short Text'   
    and   fad.entity_name = :p_entity_name -- replace with the entity_name you want to extract.   
    order by fad.pk1_value, pk2_value;
  
  cursor cur_long_text_files  
  is  
    select fad.entity_name   
          ,fad.document_id   
          ,fad.pk1_value   
          ,fad.pk2_value   
          ,fdl.long_text   
          ,(fad.entity_name || '_' || fad.document_id ||'_LT.txt') file_name   
    from fnd_attached_documents fad   
        ,fnd_documents fd   
        ,fnd_documents_long_text fdl  
        ,fnd_document_datatypes fdd   
    where fad.document_id = fd.document_id   
    and  fd.media_id      = fdl.media_id   
    and  fd.datatype_id   = fdd.datatype_id   
    and  fdd.user_name    = 'Long Text'   
    and  fad.entity_name  = :p_entity_name -- replace with the entity_name you want to extract.   
    order by fad.pk1_value, pk2_value;
   
  cursor cur_files  
  is  
    select fad.entity_name    
          ,fad.document_id   
          ,fad.pk1_value   
          ,fad.pk2_value   
          ,fd.datatype_id   
          ,(fad.entity_name || '_' || fad.document_id ||'_' || fl.file_name) file_name   
          ,fl.file_data   
    from fnd_attached_documents fad   
        ,fnd_documents fd   
        ,fnd_lobs fl  
        ,fnd_document_datatypes fdd   
    where fad.document_id = fd.document_id   
    and   fd.media_id     = fl.file_id   
    and   fd.datatype_id  = fdd.datatype_id   
    and   fdd.user_name   = 'File'   
    and   fad.entity_name = :p_entity_name -- replace with the entity_name you want to extract.   
    order by fad.pk1_value, pk2_value;
  
  cursor cur_url_files  
  is  
    select fad.entity_name   
          ,fad.document_id   
          ,fad.pk1_value   
          ,fad.pk2_value   
          ,(fad.entity_name || '_' || fad.document_id ||'_URL.txt') file_name   
          ,fd.url   
    from fnd_attached_documents fad   
        ,fnd_documents fd  
        ,fnd_document_datatypes fdd   
    where fad.document_id = fd.document_id   
    and  fd.datatype_id   = fdd.datatype_id   
    and  fdd.user_name    = 'Web Page'   
    and  fad.entity_name  = :p_entity_name -- replace with the entity_name you want to extract.   
    order by fad.pk1_value, pk2_value;
  
begin
  
  -- Short Text Attachments   
  for c_file in cur_short_text_files  
  loop  
    v_file := utl_file.fopen('XX_EXTRACT_DIR',c_file.file_name, 'W', 32764);  
    utl_file.put(v_file,c_file.short_text);  
    utl_file.fclose(v_file);   
  end loop;
  
  -- Long Text Attachments   
  for c_file in cur_long_text_files  
  loop  
    v_file := utl_file.fopen('XX_EXTRACT_DIR',c_file.file_name, 'W', 32764);  
    utl_file.put(v_file,c_file.long_text);  
    utl_file.fclose(v_file);   
  end loop;
  
  -- File Attachments  
  for c_file in cur_files  
  loop  
    v_file := utl_file.fopen('XX_EXTRACT_DIR',c_file.file_name, 'wb', 32764);  
    v_blob_len := dbms_lob.getlength(c_file.file_data);  
    v_pos := 1;  
    while v_pos < v_blob_len  
    loop  
      dbms_lob.read(c_file.file_data,v_amt,v_pos,v_buffer);  
      utl_file.put_raw(v_file,v_buffer,true);  
      v_pos := v_pos + v_amt;  
    end loop;   
    utl_file.fclose(v_file);   
  end loop;
  
  --Web Page Attachments  
  for c_file in cur_url_files  
  loop  
    v_file := utl_file.fopen('XX_EXTRACT_DIR',c_file.file_name, 'W', 32764);  
    utl_file.put(v_file,c_file.url);  
    utl_file.fclose(v_file);   
  end loop;       
end;  

No comments:

Post a Comment

Oracle Fusion - Cost Lines and Expenditure Item link in Projects

SELECT   ccd.transaction_id,ex.expenditure_item_id,cacat.serial_number FROM fusion.CST_INV_TRANSACTIONS cit,   fusion.cst_cost_distribution_...