Thursday, June 13, 2019

Excel file output from Oracle Applications concurrent request using SYLK (PCL Format type). aka Look Ma, no BIP!

Need to create Microsoft Excel style files directly operable from Oracle Applications concurrent request output ... without using BI Publisher?

A little know file format with acronym SYLK is a handy tool for create files readable in Microsoft Excel. Since I posted about Excel / CSV output from a concurrent request using Oracle BI Publisher, I figured those people that aren't quite up to the latest versions of BI Publisher / XML Publisher might find this post handy. It requires little more than PL/SQL and earlier versions of Oracle eBusiness Suite. Not only that but also aligns nicely to my thick database inclination!
So, without further ado, here's the recipe for a very simple Excel (SYLK) output concurrent program for an FND_USERS listing with creation date from/to parameters.
  1. Take a PL/SQL package based on the Oracle provided OWA_SYLK package (owasylk.sql / owa_sylk.sql) and make some changes:
    • rename it to owa_sylk_apps
    • Change it to use fnd_file.put_line(fnd_file.output instead of utl_file.put_line(g_file
    • Remove parameters for p_file
  2. Create a PL/SQL package for the concurrent program that outputs SYLK file to the concurrent request output.
    create or replace package XXXV8_USERS_SYLK_PKG AUTHID CURRENT_USER
    AS
    procedure main
    ( errbuf      out varchar2
    , retcode     out varchar2
    , p_date_from in  varchar2
    , p_date_to   in  varchar2
    );
    end XXXV8_USERS_SYLK_PKG;
    /
    
    create or replace package body XXXV8_USERS_SYLK_PKG
    AS
    procedure main
    ( errbuf      out varchar2
    , retcode     out varchar2
    , p_date_from in  varchar2
    , p_date_to   in  varchar2
    ) as
      l_date_from date;
      l_date_to   date;
    begin
      l_date_from := fnd_date.canonical_to_date(p_date_from);
      l_date_to   := fnd_date.canonical_to_date(p_date_to);
      owa_sylk_apps.show(
            p_query => 'select user_id user_id, user_name user_name, '
                       '       description description, creation_date created '
                       'from fnd_user '
                       'where trunc(creation_date) >  :DATE_FROM '
                       'and   trunc(creation_date) <= :DATE_TO ',
            p_parm_names =>
                     owa_sylk_apps.owaSylkArray( 'DATE_FROM', 'DATE_TO'),
            p_parm_values =>
                     owa_sylk_apps.owaSylkArray(l_date_from ,l_date_to),
            p_widths =>
                     owa_sylk_apps.owaSylkArray(20,20,20,20)
                     );
    end main;
    
    END XXXV8_USERS_SYLK_PKG;
    /
    
  3. Setup the concurrent program (note the Output Format PCL)



  4. Hijack one of the little used Viewer Options (PCL) so that we can get the Concurrent Request output browser to automatically open Microsoft Excel. Note this is optional, you can just create a new Viewer Option but then you may get the "Choose Viewer" box when viewing concurrent request output. NB: Navigation path is System Administrator, Install, Viewer Options
  5. update fnd_mime_types_tl
    set    mime_type = 'application/vnd.ms-excel'
    ,      description = 'Excel (SYLK) used to be application/vnd.hp-PCL: Printer Control Language'
    ,      last_updated_by = 0
    ,      last_update_date = sysdate
    where  file_format_code = 'PCL'
    and    mime_type = 'application/vnd.hp-PCL';
    
    commit;

  6. Assign the concurrent program to the appropriate request group (e.g. System Administrator, All Reports, Application Object Library) and run the concurrent program to test it all out!

And there you have it - Excel style output direct from concurrent request generated by PL/SQL!