Igor Kromin |   Consultant. Coder. Blogger. Tinkerer. Gamer.

I've been doing SQL optimisation for some of the services at work recently and saw that we've been using EXTRACTVALUE in a number of places. This is not bad in itself, however the Oracle 12c documentation states that EXTRACTVALUE is deprecated and should be replaced with XMLTABLE.
The EXTRACTVALUE function is deprecated. It is still supported for backward compatibility. However, Oracle recommends that you use the XMLTABLE function, or the XMLCAST and XMLQUERY functions instead. See XMLTABLE, XMLCAST, and XMLQUERY for more information.


Now I knew that the particular query I was looking at wasn't performing terribly great so I decided to try out XMLTABLE in it and got some amazing results. In my case the SQL execution time was 4.5 times faster when I switched to XMLTABLE!
xmltablevsextractval2.png




When I did some further investigation I found that the performance of EXTRACTVALUE depends on the number of values you get from your XMLType. This seems to scale linearly, so having two values extracted roughly doubles the time for the SQL to complete, and so on. I experimented with extracting 1 value, then 2, all the way up to 5 values with the following results...
xmltablevsextractval1.png


The XMLTABLE approach always had constant performance, no matter whether it was extracting 1 or 5 XPATHs. With EXTRACTVALUE the performance varied as described earlier - the more XPATHs the slower it was.

The format of my EXTRACTVALUE based SQL was like this...
 SQL
select
extractvalue(XMLType(t.document), '/Document/Some/Xpath[@expression]',
'http://igorkromin.net/') column1,
extractvalue(XMLType(t.document), '/Document/Some/Xpath[@expression]',
'http://igorkromin.net/') column2,
extractvalue(XMLType(t.document), '/Document/Some/Xpath[@expression]',
'http://igorkromin.net/') column3,
extractvalue(XMLType(t.document), '/Document/Some/Xpath[@expression]',
'http://igorkromin.net/') column4,
extractvalue(XMLType(t.document), '/Document/Some/Xpath[@expression]',
'http://igorkromin.net/') column5
from
my_table t
where my_id = '123'
order by 1



When converted to use XMLTABLE, the SQL had this format...
 SQL
select x.*
from
my_table t,
XMLTABLE(
xmlnamespaces(default 'http://igorkromin.net/'), '/Document'
PASSING XMLType(t.document)
COLUMNS column1 varchar2(100) PATH '/Some/Xpath[@expression]',
column2 varchar2(100) PATH '/Some/Xpath[@expression]',
column3 varchar2(100) PATH '/Some/Xpath[@expression]',
column4 varchar2(100) PATH '/Some/Xpath[@expression]',
column5 varchar2(100) PATH '/Some/Xpath[@expression]'
) x
where my_id = '123'
order by 1


Both of the SQLs return the same results, however the XMLTABLE based query runs significantly faster.

The tests were done when selecting a 1000 XML document result set from the database. The ORDER BY clause is present to force the whole result set to be processed to give accurate timing information.

So there you go, if you are still using EXTRACTVALUE and are pulling out more than 1 XPATH from your XML then it is worth switching to the new XMLTABLE approach!

-i

Have comments or feedback on what I wrote? Please share them below! Found this useful? Consider sending me a small tip.
comments powered by Disqus
Other posts you may like...
Hi! You can search my blog here ⤵
Or browse the recent top tags...

Recent Blog Posts

Oracle WebLogic Maven Plugin wsgen goal not respecting the Maven Compiler Plugin version

How to fix Google Cloud SDK dev server error - No module named ipaddr

Adorable but totally metal - Metal Earth 3D Guardians of the Galaxy Groot model kit

Riverside Expressway Cam shut down permanently

Inserting Google DFP ads with Backbone, Underscore and jQuery

How to resolve the domain is already mapped to a project error in Google App Engine

A quick look at the Nyko Super MiniBoss wireless controllers for the SNES mini

Loading and displaying a collection from bootstrapped data in Backbone.js

Add this handy function to your Bash profile file to display the compiled JDK version for a .class file

How does PCBWay stack up as a low budget PCB fab

Recent Galleries

BMB-012 Nanoblock T-Rex Skeleton Model assembly

Tiny Arcade revision 6 kit assembly and decal application

Atari Lynx repair - Part 5 - McWill LED screen mod installation

Atari Lynx repair - Part 4 - screen cover replacement

Atari Lynx repair - Part 2 - re-capping the motherboard

Atari Lynx repair - Part 3 - broken speaker replacement

Atari Lynx repair - Part 1 - introduction and case disassembly

Building a custom Atari Lynx game box storage shelf unit in a day

Protecting old Atari Lynx game boxes with snug fit plastic sleeves

Monument Valley 2 is released and does not disappoint

Blogs and Friends

Matt Moores Blog
Georgi's FlatPress Guide
Perplexing Permutations
The Security Sleuth
Ilia Rogatchevski
Travelling Fairy

Blog Activity

Blog Activity