This is an
excerpt from the book
Advanced PL/SQL: The Definitive Reference by Boobal Ganesan.
XMLELEMENT
is 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 EVALNAME
expression dynamically sets the element name and the
attribute name. The expression must return a character
value.
XMLELEMENT function is used for
constructing XML elements from the table data or a PL/SQL
variable. This function accepts
n number of
parameters, out of which its first parameter constructs the
name of the XML tag and the rest of its parameters
constructs the content of the XML element as shown below,
The prototype of the XMLELEMENT
function is shown below,
XMLELEMENT(<Element_Name>[,<Attribute_value1>[,<Attribute_value2>...]])
In the below example, the first name
and the last name of the employees whose IDs mentioned in
the WHERE condition of the SELECT statement
are constructed as
XML elements using this function.
SELECT xmlelement(Name,First_name,'
',last_name) XMLELEMENT
FROM employees
WHERE employee_id IN (100,101);
Result:
<NAME>Steven King</NAME>
<NAME>Neena Kochhar</NAME>
One XML element can be nested to a
collection of XML elements and form a nested XML element as
shown in the below snippet.
SELECT xmlelement(Name,
First_name, ' ', last_name, xmlelement(phone,
phone_number), xmlelement(email, email)) XMLELEMENT
FROM employees
WHERE employee_id IN (100,101);
Result:
<NAME>Steven
King<PHONE>515.123.4567</PHONE><EMAIL>SKING</EMAIL></NAME>
<NAME>Neena Kochhar<PHONE>515.123.4568</PHONE><EMAIL>NKOCHHAR</EMAIL></NAME>
 |
Need to learn to program with PL/SQL?
For complete notes on programming in PL/SQL, we
recommend the book
Advanced PL/SQL: The Definitive Reference by Boobal Ganesan.
This is a complete book on PL/SQL with
everything you need to know to write efficient and
complex PL/SQL code. |
|
|
|
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!

|
|
|
|
|
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.
Copyright © 1996 - 2020
All rights reserved by
Burleson
Oracle ®
is the registered trademark of Oracle Corporation.
|
|