Oracle® Text Application Developer's Guide 11g Release 2 (11.2) Part Number E24435-01 |
|
|
PDF · Mobi · ePub |
This chapter describes how to use the XML query result set interface, and includes:
A page of search results in applications can consist of many disparate elements - metadata of the first few documents, total hit counts, per-word hit counts, and so on. Generating these results in earlier versions of Oracle Text required several queries and calls — perhaps a query on the base table, a call to CTX_QUERY.COUNT_HITS
, and so on. Each extra call takes time to reparse the query and look up index metadata. Additionally, some search operations, such as iterative query refinement or breakdown top ten, are difficult for SQL. If it is even possible to construct a SQL statement to produce the desired results, such SQL is usually suboptimal.
The result set interface is able to produce the various kinds of data needed for a page of search results all at once, thus improving performance by sharing overhead. The result set interface can also return data views that are difficult to express in SQL, such as top N by category queries.
The CTX_QUERY.RESULT_SET()
API enables you to obtain query results with a single query, rather than running multiple CONTAINS()
queries to achieve the same result. For example, in order to display a search result page, the following information needs to be obtained first:
top 20 hit list sorted by date and relevancy
total number of hits for the given Text query
counts group by publication date
counts group by author
Assume the following table definition for storing documents to be searched:
create table docs ( docid number, author varchar2(30), pubdate date, title varchar2(60), doc clob);
Assume the following Oracle Text Index definition:
create index docidx on docs(doc) indextype is ctxsys.context filter by author, pubdate, title, order by pubdate;
With these definitions, you can obtain the four pieces of information for displaying the search result page by issuing four SQL statements:
-- Get top 20 hits sorted by date and relevancy select * from (select /*+ first_rows */ rowid, title, author, pubdate from docs where contains(doc, 'oracle',1)>0 order by pubdate desc, score(1) desc) where rownum < 21; -- Get total number of hits for the given Text query select count(*) from docs where contains(doc, 'oracle',1)>0; -- Get counts group by publication date select pubdate, count(*) from docs where contains(doc, 'oracle',1)>0 group by pubdate; -- Get counts group by author select author, count(*) from docs where contains(doc, 'oracle',1)>0 group by author;
As you can see, using separate SQL statements results in a resource-intensive query, as you run the same query four times. However, by using CTX_QUERY.RESULT_SET()
, you can enter all this information in one single Oracle Text query:
declare rs clob; begin dbms_lob.createtemporary(rs, true, dbms_lob.session); ctx_query.result_set('docidx', 'oracle text performance tuning', ' <ctx_result_set_descriptor> <count/> <hitlist start_hit_num="1" end_hit_num="20" order="pubDate desc, score desc"> <score/> <rowid/> <sdata name="title"/> <sdata name="author"/> <sdata name="pubDate"/> </hitlist> <group sdata="pubDate"> <count/> </group> <group sdata="author"> <count/> </group> </ctx_result_set_descriptor> ', rs); -- Put in your code here to process the Output Result Set XML dbms_lob.freetemporary(rs); exception when others then dbms_lob.freetemporary(rs); raise; end; /
The result set output will be an XML containing all the necessary information required to construct the search result page:
<ctx_result_set> <hitlist> <hit> <score>90</score> <rowid>AAAPoEAABAAAMWsAAC</rowid> <sdata name="TITLE"> Article 8 </sdata> <sdata name="AUTHOR">John</sdata> <sdata name="PUBDATE">2001-01-03 00:00:00</sdata> </hit> <hit> <score>86</score> <rowid>AAAPoEAABAAAMWsAAG</rowid> <sdata name="TITLE"> Article 20 </sdata> <sdata name="AUTHOR">John</sdata> <sdata name="PUBDATE">2001-01-03 00:00:00</sdata> </hit> <hit> <score>78</score> <rowid>AAAPoEAABAAAMWsAAK</rowid> <sdata name="TITLE"> Article 17 </sdata> <sdata name="AUTHOR">John</sdata> <sdata name="PUBDATE">2001-01-03 00:00:00</sdata> </hit> <hit> <score>77</score> <rowid>AAAPoEAABAAAMWsAAO</rowid> <sdata name="TITLE"> Article 37 </sdata> <sdata name="AUTHOR">John</sdata> <sdata name="PUBDATE">2001-01-03 00:00:00</sdata> </hit> ... <hit> <score>72</score> <rowid>AAAPoEAABAAAMWsAAS</rowid> <sdata name="TITLE"> Article 56 </sdata> <sdata name="AUTHOR">John</sdata> <sdata name="PUBDATE">2001-01-03 00:00:00</sdata> </hit> </hitlist> <count>100</count> <groups sdata="PUBDATE"> <group value="2001-01-01 00:00:00"><count>25</count></group> <group value="2001-01-02 00:00:00"><count>50</count></group> <group value="2001-01-03 00:00:00"><count>25</count></group> </groups> <groups sdata="AUTHOR"> <group value="John"><count>50</count></group> <group value="Mike"><count>25</count></group> <group value="Steve"><count>25</count></group> </groups> </ctx_result_set>
See Also:
Oracle Text Reference for syntax details and more information