add

About Me

My photo
Oracle Apps - Techno Functional consultant

Wednesday, March 28

How to Format Oracle output with HTML/XML


Question: 
How do I get a dynamic format output from Oracle?  I want to write an Oracle PL/SQL that provides XML and/or HTML formatted data dynamically.  The original of this was a "generic" way of reading the output of a stored procedure for development like the SQL Server TSQL, which formats output automatically.
Oracle SQL can be embedded in almost any popular procedural language, and Oracle PL/SQL is quite robust, allowing embedded Java. 
Oracle’s XML Publisher product has callable procedures that can retrieve Oracle data and create reports with graphs and images, and then format, mail, fax, print, or FTP them to a remote device.
For formatting Oracle output, Oracle has the dbms_xmlgenPL/SQL package. This package generates XML "on the fly" using any Oracle SQL query you want.  The dbms_xmlgenpackage is extremely easy to use from either the SQL prompt or in code, as it’s just a simple query.  

Generating formatted XML From Oracle
Take this standard query as a semple:

SQL> select employee_id, first_name, last_name, phone_number
  2  from employees where rownum < 6

EMPLOYEE_ID FIRST_NAME           LAST_NAME                 PHONE_NUMBER
----------- -------------------- ------------------       ------------
        100 Steven               King                      515.123.4567
        101 Neena                Kochhar                   515.123.4568
        102 Lex                  De Haan                   515.123.4569
        103 Alexander            Hunold                    590.423.4567
        104 Bruce                Ernst                     590.423.4568
We get our standard output, but with no formatting. It's easy to transform this Oracle output into properly formatted XML.  All we do is change the SQL to embed the requested columns into a call to the dbms_xmlgen.getxmlprocedure:

set pages 0
set linesize 150
set long 9999999
set head off
 
SQL> select dbms_xmlgen.getxml('select employee_id, first_name,
  2  last_name, phone_number from employees where rownum < 6') xml
  3  from dual
OUTPUT
 
<?xml version="1.0"?>
<ROWSET>
 <ROW>
  <EMPLOYEE_ID>100</EMPLOYEE_ID>
  <FIRST_NAME>Steven</FIRST_NAME>
  <LAST_NAME>King</LAST_NAME>
  <PHONE_NUMBER>515.123.4567</PHONE_NUMBER>
 </ROW>
 <ROW>
  <EMPLOYEE_ID>101</EMPLOYEE_ID>
  <FIRST_NAME>Neena</FIRST_NAME>
  <LAST_NAME>Kochhar</LAST_NAME>
  <PHONE_NUMBER>515.123.4568</PHONE_NUMBER>
 </ROW>
 <ROW>
  <EMPLOYEE_ID>102</EMPLOYEE_ID>
  <FIRST_NAME>Lex</FIRST_NAME>
  <LAST_NAME>De Haan</LAST_NAME>
  <PHONE_NUMBER>515.123.4569</PHONE_NUMBER>
 </ROW>
 <ROW>
  <EMPLOYEE_ID>103</EMPLOYEE_ID>
  <FIRST_NAME>Alexander</FIRST_NAME>
  <LAST_NAME>Hunold</LAST_NAME>
  <PHONE_NUMBER>590.423.4567</PHONE_NUMBER>
 </ROW>
 <ROW>
  <EMPLOYEE_ID>104</EMPLOYEE_ID>
  <FIRST_NAME>Bruce</FIRST_NAME>
  <LAST_NAME>Ernst</LAST_NAME>
  <PHONE_NUMBER>590.423.4568</PHONE_NUMBER>
 </ROW>
</ROWSET>
Fully compliant XML that can be easily integrated into any application, with ROWSET and ROW tags in place to identify nodes, and tags for each column you pulled out of the database.
All we had to do was wrap the query in the DBMS_XMLGEN.GETXMLfunction call, selected from DUAL. The query remained exactly the same.
 
Advanced formatting of Oracle data
Let’s take this easy formatting one step further and show how Oracle automatically formats hierarchical reports. Most XML has subnodes for each main node, allowing a formatted hierarchy. For example, assume we wanted to pull XML for every department, and a subnode for every employee under it? For this formatting, we use the CURSOR function!
 
SQL> select department_id, department_name,
  2  cursor(select first_name, last_name
  3  from employees e
  4  where e.department_id = d.department_id) emp_row
  5  from departments d
  6* where rownum < 4
 
DEPARTMENT_ID DEPARTMENT_NAME                EMP_ROW
------------- ------------------------------ --------------------
           10 Administration                 CURSOR STATEMENT : 3
 
CURSOR STATEMENT : 3
 
FIRST_NAME           LAST_NAME
-------------------- -------------------------
Jennifer             Whalen
 
           20 Marketing                      CURSOR STATEMENT : 3
 
CURSOR STATEMENT : 3
 
FIRST_NAME           LAST_NAME
-------------------- -------------------------
Michael              Hartstein
Pat                  Fay
 
           30 Purchasing                     CURSOR STATEMENT : 3
 
CURSOR STATEMENT : 3
 
FIRST_NAME           LAST_NAME
-------------------- -------------------------
Den                  Raphaely
Alexander            Khoo
Shelli               Baida
Sigal                Tobias
Guy                  Himuro
Karen                Colmenares
 
6 rows selected.

The results don’t look too impressive at the SQL prompt. However, watch as we surround it with a call to DBMS_XMLGEN.GETXML:

 
SQL> select dbms_xmlgen.getxml('
  2  select department_id, department_name,
  3  cursor(select first_name, last_name
  4  from employees e
  5  where e.department_id = d.department_id) emp_row
  6  from departments d
  7  where rownum < 4
  8* ') from dual
 
<?xml version="1.0"?>
<ROWSET>
 <ROW>
  <DEPARTMENT_ID>10</DEPARTMENT_ID>
  <DEPARTMENT_NAME>Administration</DEPARTMENT_NAME>
  <EMP_ROW>
   <EMP_ROW_ROW>
    <FIRST_NAME>Jennifer</FIRST_NAME>
    <LAST_NAME>Whalen</LAST_NAME>
   </EMP_ROW_ROW>
  </EMP_ROW>
 </ROW>
 <ROW>
  <DEPARTMENT_ID>20</DEPARTMENT_ID>
  <DEPARTMENT_NAME>Marketing</DEPARTMENT_NAME>
  <EMP_ROW>
   <EMP_ROW_ROW>
    <FIRST_NAME>Michael</FIRST_NAME>
    <LAST_NAME>Hartstein</LAST_NAME>
   </EMP_ROW_ROW>
   <EMP_ROW_ROW>
    <FIRST_NAME>Pat</FIRST_NAME>
    <LAST_NAME>Fay</LAST_NAME>
   </EMP_ROW_ROW>
  </EMP_ROW>
 </ROW>
 <ROW>
  <DEPARTMENT_ID>30</DEPARTMENT_ID>
  <DEPARTMENT_NAME>Purchasing</DEPARTMENT_NAME>
  <EMP_ROW>
   <EMP_ROW_ROW>
    <FIRST_NAME>Den</FIRST_NAME>
    <LAST_NAME>Raphaely</LAST_NAME>
   </EMP_ROW_ROW>
   <EMP_ROW_ROW>
    <FIRST_NAME>Alexander</FIRST_NAME>
    <LAST_NAME>Khoo</LAST_NAME>
   </EMP_ROW_ROW>
   <EMP_ROW_ROW>
    <FIRST_NAME>Shelli</FIRST_NAME>
    <LAST_NAME>Baida</LAST_NAME>
   </EMP_ROW_ROW>
   <EMP_ROW_ROW>
    <FIRST_NAME>Sigal</FIRST_NAME>
    <LAST_NAME>Tobias</LAST_NAME>
   </EMP_ROW_ROW>
   <EMP_ROW_ROW>
    <FIRST_NAME>Guy</FIRST_NAME>
    <LAST_NAME>Himuro</LAST_NAME>
   </EMP_ROW_ROW>
   <EMP_ROW_ROW>
    <FIRST_NAME>Karen</FIRST_NAME>
    <LAST_NAME>Colmenares</LAST_NAME>
   </EMP_ROW_ROW>
  </EMP_ROW>
 </ROW>
</ROWSET>

Note that the query only added dbms_xmlgen.getxml('
We have each DEPARTMENT as a ROW tag, and the cursor we created gives us an EMP_ROW node containing recurring EMP_ROW_ROW nodes.
  
Conclusions on dbms_xmlgen
The dbms_xmlgenprocedure can be extremely useful for quick retrieval of Oracle records, formatted for web browser display. With these formatting procedures you can display the output of any query directly to the screen, and you have an easy XML display program. The best part comes with easily formatting Oracle reports. XML Publisher is made to accept XML that looks just like this and form extremely detailed reports using templates made in Microsoft Word.
With queries such as these and XML Publisher you can have a full reporting suite that easily pulls data, forms it into a PDF, DOC, XLS, or HTML report, and distributes it anywhere you would like it to go.

No comments: