Igor's Blog
Programming, DIY, Games, Hacks, and Tech

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

comments powered by Disqus
Other posts you may like...

Recent Blog Posts

A hack to create an uber jar with the Maven Shade Plugin using local jar files

Is it worth it? Apple USB-C Digital Multi AV adapter vs a cheap eBay clone

Running X11 graphical applications after changing to another user using 'sudo su'

How to stop Facebook using ad images as post sharing thumbnails

Picking lists for Atari Lynx capacitor replacement kits

Performance - 2012 Retina MacBook Pro vs 2017 MacBook Pro

Look and feel - 2012 Retina MacBook Pro vs 2017 MacBook Pro

Using math to work out the diameter of hard to reach water cooling pipes

How to get the unreachable shard in the Hinterlands in DragonAge Inquisition

Measy RC12 wireless 2.4Ghz keyboard touchpad review

Recent Galleries

Monument Valley 2 is released and does not disappoint

Space Food - Chocolate Ice Cream with Chocolate Chips

Legeod Star Wars AT-DP kit

DIY spare parts computer build with a RAIDMAX Anura case

Fake 'Lepin' brand Lego packaging

Hardwood garden bench with clear resin void filler

Fixing a 3D printer extruder that stopped heating up

Easily increase disk space in a Lenovo Ideapad 100S 14" laptop with an M.2 SSD

Making a multi-piece 3D printed solder spool holder stand

DIY indoor apartment grow light wiring

My Other Web Sites

Igor and Elise's Travels
Riverside Expressway Cam
300 George St Blogumentary

My Online Tools

UUID to OID Converter
Guru JSON-RPC Tester
Extrudifier Object Designer
Travel ┬ÁBlog

Blogs and Friends

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

Blog Activity

Blog Activity
Don't forget to
me for more great articles!
Don't show this again