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 XMLAGG tips

Oracle PL/SQL tips by Boobal Ganesan

This is an excerpt from the book Advanced PL/SQL: The Definitive Reference by Boobal Ganesan.

The XMLAGG function takes a list of XML elements from one column and returns an aggregated XML document in a single cell.

 

% Note: XMLAGG is an aggregate function.

The prototype of the XMLAGG function is shown below,

 

XMLAGG(<XML_ELEMENT> ORDER BY <VALUE>)

 

In the below listing, the XMLAGG function aggregates the XML element of the first name of two employees into a single cell XML data.

 

SELECT xmlagg(xmlforest(First_name) order by first_name) XMLAGG

FROM employees

WHERE employee_id IN (100,101);

 

Result:

<FIRST_NAME>Neena</FIRST_NAME><FIRST_NAME>Steven</FIRST_NAME>

 

But this result misses an enclosing parent tag to make it an XML document, which can be formed wrapping this query with the XMLELEMENT function as shown below,

 

SELECT xmlelement(Names,xmlagg(xmlforest(First_name) order by first_name)) XMLAGG

FROM employees

WHERE employee_id IN (100,101);

 

Result:

<NAMES><FIRST_NAME>Neena</FIRST_NAME><FIRST_NAME>Steven</FIRST_NAME></NAMES>

 

Prior to the creation of the LISTAGG function in the version 11gR2, XMLAGG was used for aggregating the column values. The below statement imitates the functioning of the LISTAGG function.

 

SELECT REPLACE(REPLACE(REPLACE(xmlagg(xmlforest(First_name)

ORDER BY first_name),'</FIRST_NAME><FIRST_NAME>',','),'<FIRST_NAME>'),'</FIRST_NAME>') XMLAGG

FROM employees

WHERE employee_id IN (100,101);

 

Result:

Neena,Steven

In Oracle 9i and beyond we can use the xmlagg function to aggregate multiple rows onto one column:

select
   deptno,
   rtrim (xmlagg (xmlelement (e, ename || ',')).extract ('//text()'), ',') enames
from
   emp
group by
   deptno
;

    DEPTNO ENAMES                                 
---------- ----------------------------------------
        10 CLARK,MILLER,KING                      
        20 SMITH,FORD,ADAMS,SCOTT,JONES           
        30 ALLEN,JAMES,TURNER,BLAKE,MARTIN,WARD 

XMLAGG is used to aggregate multiple rows in a single XML document:

SELECT
   XMLELEMENT
   (
      EMP,
      XMLAGG
      (
         XMLELEMENT
         (
            DEPT,
            XMLATTRIBUTES(DEPTNO),
            XMLAGG
            (
               XMLELEMENT
               (
                  NAME,
                  ENAME
               )
               ORDER BY
                  ENAME
            )
         )
         ORDER BY
            DEPTNO
      )
  )
FROM
   EMP
GROUP BY

   DEPTNO;

EMP
----------------------------
<EMP>
   <DEPT DEPTNO="10">
      <NAME>CLARK</NAME>
      <NAME>KING</NAME>
      <NAME>MILLER</NAME>
   </DEPT>
   <DEPT DEPTNO="20">
      <NAME>ADAMS</NAME>
      <NAME>FORD</NAME>
      <NAME>JONES</NAME>
      <NAME>SCOTT</NAME>
     
<NAME>SMITH</NAME>
   </DEPT>
   <DEPT DEPTNO="30">
      <NAME>ALLEN</NAME>
     
<NAME>BLAKE</NAME>
      <NAME>JAMES</NAME>
      <NAME>MARTIN</NAME>
      <NAME>TURNER</NAME>
      <NAME>WARD</NAME>
   </DEPT>
</EMP>

The inner XMLAGG function aggregates the employees in each department and the outer XMLAGG aggregates the department in the whole table. The result is a well structured document that displays all the employees.

 

 

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!

Oracle 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