Tuesday 16 October 2007

Load XML into Database

Following is the extract from Oracle SQL & PLSQL Forum (Courtesy Billy Verreynne)

You can store XML as CLOB or XMLType objects.

You can easily load XML files into the database as CLOBs using the DBMS_LOB PL/SQL package - it has a load-from-file procedural call that can be made. Very easy to use.


drop table xml_clob;
drop table my_objects;
-- create a table to store a large XML doc in raw format
create table xml_clob ( doc CLOB )
/
-- create such a raw XML document, using the ALL_OBJECTS -- table
DECLARE
CURSOR curxml IS
SELECT xmlelement("ORA_OBJECT", xmlforest(object_id AS "ID", owner AS "OWNER", object_type AS "TYPE", object_name AS "NAME")) AS "XML_DATA"
FROM all_objects
WHERE rownum < 100001;

xml XMLTYPE;
c CLOB;
BEGIN
dbms_lob.createtemporary(c, TRUE);

OPEN curxml;

LOOP
FETCH curxml
INTO xml;

EXIT WHEN curxml%NOTFOUND;
DBMS_LOB.Append( c, xml.GetCLOBVal() );
-- dbms_lob.writeappend(c, LENGTH(xml.getclobval()), xml.getclobval());
END LOOP;

CLOSE curxml;

INSERT INTO xml_clob
VALUES ('' || c || ''
);

COMMIT;
END;

/
CREATE TABLE my_objects (obj_id NUMBER, obj_owner VARCHAR2(30), obj_type VARCHAR2(19), obj_name VARCHAR2(30) )

/
-- call proc with a raw XML clob and have it insert the contents
-- into a relational table
CREATE OR REPLACE PROCEDURE insertobjects(
xmldoc IN OUT NOCOPY CLOB
) IS
BEGIN
INSERT INTO my_objects
SELECT extractvalue(VALUE(xml), 'ORA_OBJECT/ID')
, extractvalue(VALUE(xml), 'ORA_OBJECT/OWNER')
, extractvalue(VALUE(xml), 'ORA_OBJECT/TYPE')
, extractvalue(VALUE(xml), 'ORA_OBJECT/NAME')
FROM TABLE(SELECT xmlsequence(EXTRACT(XMLTYPE(xmldoc), 'DATASET/*'))
FROM dual) xml;

COMMIT;
END;
/
-- the test (processing 10,000 XML rows):
set timing on
declare c CLOB;
BEGIN
SELECT doc
INTO c
FROM xml_clob;

insertobjects(c);
END;
/

set timing offselect count(*) from my_objects;
select * from my_objects where rownum < 4;
--eof

Monday 15 October 2007

Extracting from XML Datatype



WITH XMLDATA AS
(SELECT xmltype(
'<?xml version="1.0" encoding="utf-8"?>
<transaction type="IN">
<customer id="Cust001"/>
<product>
<product_details>
<orderno>ORD000001</orderno>
<orderlineno>000010</orderlineno>
<product_code>PRD</product_code>
<product_content>
<URL/>
<product_one>
<textType>1</textType>
<text/>
<text1>Surrounding Areas</text1>
<iconCreditCards boolean="false"/>
<messagingEmailAddress>myemailAddress@email.com</messagingEmailAddress>
</product_one>
</product_content>
<live_date>2007-02-21</live_date>
<term_date>2008-03-05</term_date>
<proposed_start_date>2007-03-07</proposed_start_date>
</product_details>
<classification code="00001">
<branch bf_id="0001">
<suppress_address boolean="false"/>
<branch_override_details>
<telephone_number prefix="Tel">01234 567890</telephone_number>
</branch_override_details>
<organisation_name>SIGNAL</organisation_name>
<address_line1>Address Line 1, Some Road</address_line1>
<address_line2/>
<address_line3/>
<locality>London</locality>
<post_town>PostTown</post_town>
<postcode>PO1 BO1</postcode>
<telephone_number>02314 555000</telephone_number>
<telephone_number_2 prefix="Mobile">07834 123123</telephone_number_2>
</branch>
<branch bf_id="0002">
<suppress_address boolean="true"/>
<branch_override_details>
<telephone_number prefix="Tel">01234 567891</telephone_number>
</branch_override_details>
<organisation_name>SIGNAL</organisation_name>
<address_line1>Adress Line 1, Street Road</address_line1>
<address_line2/>
<address_line3/>
<locality>Best Locality</locality>
<post_town>Wonderful Town</post_town>
<postcode>PO1 CD2</postcode>
<telephone_number>01189 118118</telephone_number>
<telephone_number_2 prefix="Mobile">07834 123456</telephone_number_2>
</branch>
</classification>
</product>
</transaction>'
') XML FROM DUAL)
SELECT
extractValue(xml,'/transaction/customer@id') as CustomerID,
extractValue(xml,'/transaction/product/product_details/live_date') as startDate,
extractValue(xml,'/transaction/product/product_details/orderno') as orderno,
extractValue(xml,'/transaction/product/product_details/product_content/product_one/messagingEmailAddress') as Email,
extractValue(value(d),'/branch@bf_id') branch,
extractValue(value(d),'/branch/suppress_address@boolean') AddressSuppress,
extractValue(value(d),'/branch/branch_override_details/telephone_number@prefix') TelPrefix,
extractValue(value(d),'/branch/branch_override_details/telephone_number') TelNo
FROM XMLDATA x,
table(xmlsequence(extract(x.xml,'/transaction/product//classification/branch'))) d
/

---------- ---------- ---------- -------------------------- ------ --------------- ----------- -------------
CUSTOMERID STARTDATE ORDERNO EMAIL BRANCH ADDRESSSUPPRESS TELPREFIX TELNO
---------- ---------- ---------- -------------------------- ------ --------------- ----------- -------------
Cust001 2007-02-21 ORD000001 myemailAddress@email.com 0001 false Tel 01234 567890
Cust001 2007-02-21 ORD000001 myemailAddress@email.com 0002 true Tel 01234 567891
---------- ---------- ---------- -------------------------- ------ --------------- ----------- -------------

PIVOT Table using XML

Rows to Column

I want to get output of multiple rows into single variable seperated by comma. How can I achieve that. There is also requirement of using dynamic sql as table and column will be known at runtime only.

Here is the example :

select rtrim(dbms_xmlgen.getxmltype('select empno '','' e from EMP WHERE DEPTNO = '&p_deptno).extract('//text()'),',') x
from dual;

Enter value for p_deptno: 10

X
--------------
7782,7839,7934



Columns to Rows
I've got comma seperated values in single row, now I need the output in multiple rows. How can I get this?






EMPNO
------
7782
7839
7934

3 rows selected.