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

A quick disclaimer...

Although I put in a great effort into researching all the topics I cover, mistakes can happen. Use of any information from my blog posts should be at own risk and I do not hold any liability towards any information misuse or damages caused by following any of my posts.

All content and opinions expressed on this Blog are my own and do not represent the opinions of my employer (Oracle). Use of any information contained in this blog post/article is subject to this disclaimer.
Hi! You can search my blog here ⤵
NOTE: (2022) This Blog is no longer maintained and I will not be answering any emails or comments.

I am now focusing on Atari Gamer.