Call now: 252-767-6166  
Oracle Training Oracle Support Development Oracle Apps

 
 Home
 E-mail Us
 Oracle Articles
New Oracle Articles


 Oracle Training
 Oracle Tips

 Oracle Forum
 Class Catalog


 Remote DBA
 Oracle Tuning
 Emergency 911
 RAC Support
 Apps Support
 Analysis
 Design
 Implementation
 Oracle Support


 SQL Tuning
 Security

 Oracle UNIX
 Oracle Linux
 Monitoring
 Remote s
upport
 Remote plans
 Remote
services
 Application Server

 Applications
 Oracle Forms
 Oracle Portal
 App Upgrades
 SQL Server
 Oracle Concepts
 Software Support

 Remote S
upport  
 Development  

 Implementation


 Consulting Staff
 Consulting Prices
 Help Wanted!

 


 Oracle Posters
 Oracle Books

 Oracle Scripts
 Ion
 Excel-DB  

Don Burleson Blog 


 

 

 


 

 

 
 

Oracle XMLTABLE tips

Oracle Database Tips by Burleson Consulting

June 5, 2016

The XMLTABLE function returns the content of an XML document or an element in a relational table format.

 

The prototype for defining a XMLTABLE function is shown below,

 

SELECT * FROM <Table_name>, XMLTABLE(<Root_node> Passing <Table_name.XML_Column_name> Columns <Child_node_name1> <Data_type> path <Child_node1> <Child_node_name2> <Data_type> path <Child_node2> ... );

 

For understanding this function, the below demo table and data are created in the database.

 

CREATE TABLE Employee_details

  (Name VARCHAR2(30),Details xmltype

  );

 

INSERT INTO employee_details VALUES ('Yegappan Alagappan',

    '<Employee>

<DOB>1980-04-01</DOB>

<Designation>Technical Architect</Designation>

<Hire_date>2015-05-18</Hire_date>

<Job_ID>1011025</Job_ID>

<Salary>55000 $</Salary></Employee>'

  );

 

INSERT INTO employee_details VALUES ('Sivaramakrishnan',

    '<Employee>

<DOB>1988-08-16</DOB>

<Designation>Technical Lead</Designation>

<Hire_date>2016-05-18</Hire_date>

<Job_ID>1011024</Job_ID>

<Salary>35000 $</Salary></Employee>'

  );

 

INSERT INTO employee_details VALUES ('Thiyagu Thanthoni',

    '<Employee>

<DOB>1981-03-24</DOB>

<Designation>Vice President</Designation>

<Hire_date>2016-07-21</Hire_date>

<Job_ID>1011023</Job_ID>

<Salary>40000 $</Salary></Employee>'

  );

 

INSERT INTO employee_details VALUES ('Karthick Natarajan',

    '<Employee>

<DOB>1988-02-14</DOB>

<Designation>Senior Manager</Designation>

<Hire_date>2016-09-23</Hire_date>

<Job_ID>1011022</Job_ID>

<Salary>30000 $</Salary></Employee>'

  );

 

INSERT INTO employee_details VALUES ('Avinash Kamal',

    '<Employee>

<DOB>1988-07-27</DOB>

<Designation>Senior Software Engineer</Designation>

<Hire_date>2016-09-29</Hire_date>

<Job_ID>1011021</Job_ID>

<Salary>20000 $</Salary></Employee>'

  );

 

INSERT INTO employee_details VALUES ('Charles Jagan',

    '<Employee>

<DOB>1988-05-01</DOB>

<Designation>Analyst-I Application Programmer</Designation>

<Hire_date>2016-07-24</Hire_date>

<Job_ID>101101</Job_ID>

<Salary>10000 $</Salary></Employee>'

  );

 

Commit;

 

table EMPLOYEE_DETAILS created.

1 rows inserted.

1 rows inserted.

1 rows inserted.

1 rows inserted.

1 rows inserted.

committed.

 

When the XMLTYPE column of the EMPLOYEE_DETAILS table is passed as an input to the XMLTABLE function with appropriate paths, suitable data types and joined with its underlying table, the SQL returns a relation view of the XML document as shown below,

 

SELECT employee_details.name,

  emp.*

FROM employee_details, xmltable('/Employee' passing employee_details.details columns

DOB DATE path '/Employee/DOB',

Designation VARCHAR2(100) path '/Employee/Designation',

Hire_date DATE path '/Employee/Hire_date',

Job_ID NUMBER path '/Employee/Job_ID',

Salary VARCHAR2(10) path '/Employee/Salary') Emp

ORDER BY employee_details.name ASC;

Result Set:

NAME

DOB

DESIGNATION

HIRE_DATE

JOB_ID

SALARY

Avinash Kamal

27-JUL-88

Senior Software Engineer

29-SEP-16

1011021

20000 $

Charles Jagan

01-MAY-88

Analyst-I Application Programmer

24-JUL-16

101101

10000 $

Karthick Natarajan

14-FEB-88

Senior Manager

23-SEP-16

1011022

30000 $

Sivaramakrishnan

16-AUG-88

Technical Lead

18-MAY-16

1011024

35000 $

Thiyagu Thanthoni

24-MAR-81

Vice President

21-JUL-16

1011023

40000 $

Yegappan Alagappan

01-APR-80

Technical Architect

18-MAY-15

1011025

55000 $



=========================================================

XMLTABLE processes an XQuery program and returns rows.

SELECT
   XMLELEMENT(N,COLUMN_VALUE) N
FROM
   XMLTABLE
   (
      '1 to 10'
   );

N
----------
< N>1</N>
< N>2</N>
< N>3</N>
< N>4</N>
< N>5</N>
< N>6</N>
< N>7</N>
< N>8</N>
< N>9</N>
< N>10</N>

The very short XQuery program returns a sequence of numbers from 1 to 10. XMLTABLE returns a row for each value.

XQUERY programs can generate rows like XMLSEQUENCE.

SELECT
   NAME
FROM
   WORLD,
   XMLTABLE
   ('
      for $CANTON in $COUNTRY/COUNTRY/CANTON_LIST/CANTON
      where $CANTON//LANGUAGE="Italian"
      order by $CANTON/@ID
      return $CANTON
   '
   PASSING
      OBJECT_VALUE
   AS
      COUNTRY
   COLUMNS
      NAME XMLTYPE PATH '/CANTON/NAME'
   ); 

NAME
---------------------------
< NAME>Graubuenden</NAME>
< NAME>Ticino</NAME>

XMLTABLE processes the COUNTRY and returns a row for each canton where the language Italian exists. The rows are sorted by ID and the column NAME is returned for the name of the canton.

XMLEXISTS (11gR1) is a Boolean function similar to EXISTSNODEwith the XQuery syntax.

SELECT
   XMLFOREST(EMPNO, ENAME, JOB)
FROM
   EMP
WHERE
   XMLEXISTS
   (
      '/[JOB="ANALYST"]'
      PASSING
      XMLFOREST(EMPNO, ENAME, JOB)
   ); 

XMLFOREST(EMPNO,ENAME,JOB)
----------------------------------------
< EMPNO>7788</EMPNO>
< ENAME>SCOTT</ENAME>
< JOB>ANALYST</JOB> 

<EMPNO>7902</EMPNO>
< ENAME>FORD</ENAME>
< JOB>ANALYST</JOB>

The XPATH expression searches for analysts in the generated content.

Besides selecting literals and column values, XQuery has multiple functions. The function ora:viewis an Oracle-specific addition to the XQuery language that queries a relational table or view:

SELECT
   *
FROM
   XMLTABLE
   (
      '
         for $i in ora:view("EMP"), $j in ora:view("DEPT")
         where $i//JOB="ANALYST" and $i//DEPTNO=$j//DEPTNO
         return (<EMP>{$i//EMPNO}{$i//ENAME}{$j//DNAME}</EMP>)
      '
      COLUMNS
         EMP XMLTYPE PATH '/EMP'
   );

EMP
-------------------------------------------------------------------------
< EMP><EMPNO>7902</EMPNO><ENAME>FORD</ENAME><DNAME>RESEARCH</DNAME></EMP>
< EMP><EMPNO>7788</EMPNO><ENAME>SCOTT</ENAME><DNAME>RESEARCH</DNAME></EMP>

---------------------------------------------------------------------------
| Id  | Operation          | Name | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |      |     1 |    59 |     7  (15)| 00:00:01 |
|*  1 |  HASH JOIN         |      |     1 |    59 |     7  (15)| 00:00:01 |
|*  2 |   TABLE ACCESS FULL| EMP  |     1 |    39 |     3   (0)| 00:00:01 |
|   3 |   TABLE ACCESS FULL| DEPT |     4 |    80 |     3   (0)| 00:00:01 |
---------------------------------------------------------------------------

The XML Query selects directly from the EMP and DEPT tables. Note the execution plan: Oracle is doing a hash join of EMP and DEPT, which means the XML Query is analyzed before execution and the optimizer chooses the best possible execution plan. The columns clause defines the name and datatype of the columns that are returned. Without the columns clause, only one column named COLUMN_NAME containing an XMLTYPE is returned. The path string identifies the location of the column within the XML hierarchy.

XML Query can now be an expression.

CREATE TABLE
   T
AS
SELECT
   TABLE_NAME
FROM
   USER_TABLES;
SELECT
   TABLE_NAME,
   C
FROM
   T,
   XMLTABLE
   (
      (
         SELECT
            '
               let $j := ora:view("'||T.TABLE_NAME||'")
               return <c>{count($j)}</c>
            '
         FROM
            DUAL
      )
      COLUMNS C NUMBER PATH '/C'
   );

TABLE_NAME                              C
------------------------------ ----------
SALGRADE                                5
BONUS                                   0
EMP                                    14
DEPT                                    4

The query is built dynamically. The table name here is selected from table T, so it could be any expression.


 


   
Oracle Training from Don Burleson 

The best on site "Oracle training classes" are just a phone call away! You can get personalized Oracle training by Donald Burleson, right at your shop!

Oracle training
 
 


  Oracle consulting and training

 

Burleson is the American Team

Note: This Oracle documentation was created as a support and Oracle training reference for use by our DBA performance tuning consulting professionals.  Feel free to ask questions on our Oracle forum.

Verify experience! Anyone considering using the services of an Oracle support expert should independently investigate their credentials and experience, and not rely on advertisements and self-proclaimed expertise. All legitimate Oracle experts publish their Oracle qualifications.

Errata?  Oracle technology is changing and we strive to update our BC Oracle support information.  If you find an error or have a suggestion for improving our content, we would appreciate your feedback.  Just  e-mail:  

and include the URL for the page.


                    









Burleson Consulting

The Oracle of Database Support

Oracle Performance Tuning

Remote DBA Services


 

Copyright © 1996 -  2020

All rights reserved by Burleson

Oracle ® is the registered trademark of Oracle Corporation.

 

 

��  
 
 
Oracle Training at Sea
 
 
 
 
oracle dba poster
 

 
Follow us on Twitter 
 
Oracle performance tuning software 
 
Oracle Linux poster