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 


 

 

 


 

 

 

 
 

XML Instance

Oracle Tips by Laurent Schneider

 

Laurent Schneider is considered one of the top Oracle SQL experts, and he is the author of the book "Advanced SQL Programming" by Rampant TechPress.  The following is an excerpt from the book.

 

XML

XML functionality is part of the Oracle Database.  

XML Instance

An instance could be a well-formed XML document. An XML document contains a root node:

<DOC>
   <ELEM id="1"/>
   <ELEM id="2"/>
</DOC> 

An instance could be well-formed XML content. XML content does not require a root node:

<ELEM>1</ELEM>
<ELEM>2</ELEM>

An XML instance could also contains simple data:

1000

XMLTYPE

XMLTYPEis the datatype used to store XML data. The type constructor accepts different input like character, binary or ref cursor. The text passed to the constructor must be a well-formed document. 

SELECT
   XMLTYPE
   (
      '<X/>'
   )
FROM
   DUAL;
 

XMLTYPE
-------
<X/>

The XMLTYPE is constructed from a character literal.

SELECT
   XMLTYPE
   (
      TO_BLOB
      (
         HEXTORAW ('3C696D673E3A2D293C2F696D673E')
      ),
      NLS_CHARSET_ID('WE8MSWIN1252')
   )
FROM
   DUAL;

XMLTYPE(TO_BLOB
---------------
<img>:-)</img>

A BLOBis passed to the XMLTYPE constructor.

NLS_CHARSET_IDreturns the character set used for the encoding of the BLOB. Oracle 9i does not support BLOB as input.

SELECT
   XMLTYPE
   (
      BFILENAME('TEMP', 'test.xml'),
      NLS_CHARSET_ID('WE8MSWIN1252')
   )
FROM
   DUAL;

XMLTYPE(BFILENAME('TEM
----------------------
<msg>Hello World</msg>

A file is passed to the XMLTYPE constructor. BFILENAME returns a BFILElocator to the file test.xml in the Oracle directory TEMP.

SELECT
   XMLTYPE
   (
      CURSOR
      (           
         SELECT
            *
         FROM
            DEPT
      )
   )
FROM
   DUAL;

XMLTYPE(CURSOR(SELECT*FROMDEPT))
--------------------------------
<?xml version="1.0"?>
<ROWSET>
 <ROW>
  <DEPTNO>10</DEPTNO>
  <DNAME>ACCOUNTING</DNAME>
  <LOC>NEW YORK</LOC>
 </ROW>
 <ROW>
  <DEPTNO>20</DEPTNO>
  <DNAME>RESEARCH</DNAME>
  <LOC>DALLAS</LOC>
 </ROW>
 <ROW>
  <DEPTNO>30</DEPTNO>
  <DNAME>SALES</DNAME>
  <LOC>CHICAGO</LOC>
 </ROW>
 <ROW>
  <DEPTNO>40</DEPTNO>
  <DNAME>OPERATIONS</DNAME>
  <LOC>BOSTON</LOC>
 </ROW>
</ROWSET>

XMLTYPE accepts a Ref Cursor as a parameter.

XMLELEMENT

XMLELEMENTis a function that returns an XMLTYPE. The first argument is the name of the tag. The following argument is the value and could be string, XMLTYPE, number, or date.

SELECT
   EMPNO,
   XMLELEMENT(NAME, ENAME) NAME
FROM
   EMP
WHERE
   ENAME LIKE 'S%';
     EMPNO NAME
---------- ------------------------------
      7369 <NAME>SMITH</NAME>
      7788 <NAME>SCOTT</NAME>

XMLELEMENT generates an XML type with a tag NAME and the employee name as value.

XMLELEMENT can be nested and can contain attributes:

SELECT
   EMPNO,
   XMLELEMENT
   (
      EMP,
      XMLATTRIBUTES
      (
         EMPNO,
         DEPTNO
      ),
      XMLELEMENT
      (
         NAME,
         ENAME
      ),
      XMLELEMENT
      (
         JOB,
         JOB
      )
   ) EMP
FROM
   EMP
WHERE
   ENAME LIKE 'S%';

EMP
------------------------------------------------------------------------
<EMP EMPNO="7369" DEPTNO="20"><NAME>SMITH</NAME><JOB>CLERK</JOB></EMP>
<EMP EMPNO="7788" DEPTNO="20"><NAME>SCOTT</NAME><JOB>ANALYST</JOB></EMP>

The EMP element contains two attributes - the employee number and the department number - and two sub elements, the name and the job.

Starting with 10gR2, not only the value of the element could be an expression, but also the name of the element.

SELECT
   XMLELEMENT
   (
      EVALNAME ENAME,
      XMLATTRIBUTES
      (
         EMPNO AS EVALNAME JOB||'_ID'
      )
   ) EMP
FROM
   EMP
WHERE
   ENAME LIKE 'S%';

EMP
-----------------------------------
<SMITH CLERK_ID="7369"></SMITH>
<SCOTT ANALYST_ID="7788"></SCOTT>

The EVALNAMEexpression dynamically sets the element name and the attribute name. The expression must return a character value.


 

 

��  
 
 
Oracle Training at Sea
 
 
 
 
oracle dba poster
 

 
Follow us on Twitter 
 
Oracle performance tuning software 
 
Oracle Linux poster
 
 
 

 

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.