This chapter provides reference information for using the CTX_DDL
PL/SQL package to create and manage the preferences, section groups, and stoplists required for Text indexes.
CTX_DDL
contains the following stored procedures and functions:
Name | Description |
---|---|
ADD_ATTR_SECTION | Adds an attribute section to an XML section group. |
ADD_FIELD_SECTION | Creates a field section and assigns it to the specified section group. |
ADD_INDEX | Adds an index to a catalog index preference. |
ADD_MDATA | Changes the MDATA value of a document. |
ADD_MDATA_COLUMN | Maps a FILTER BY column to the specified MDATA section. |
ADD_MDATA_SECTION | Adds an MDATA metadata section to a document. |
ADD_NDATA_SECTION | Adds an NDATA section to a document. |
ADD_SDATA_COLUMN | Maps a FILTER BY column to the specified SDATA section. |
ADD_SDATA_SECTION | Adds an SDATA structured data section to a document. |
ADD_SPECIAL_SECTION | Adds a special section to a section group. |
ADD_STOPCLASS | Adds a stopclass to a stoplist. |
ADD_STOP_SECTION | Adds a stop section to an automatic section group. |
ADD_STOPTHEME | Adds a stoptheme to a stoplist. |
ADD_STOPWORD | Adds a stopword to a stoplist. |
ADD_SUB_LEXER | Adds a sub-lexer to a multi-lexer preference. |
ADD_ZONE_SECTION | Creates a zone section and adds it to the specified section group. |
COPY_POLICY | Creates a copy of a policy. |
CREATE_INDEX_SET | Creates an index set for CTXCAT index types. |
CREATE_POLICY | Creates a policy to use with ORA:CONTAINS() . |
CREATE_PREFERENCE | Creates a preference in the Text data dictionary. |
CREATE_SECTION_GROUP | Creates a section group in the Text data dictionary. |
CREATE_SHADOW_INDEX | Creates a policy for the passed-in index. For non-partitioned index, also creates an index table. |
CREATE_STOPLIST | Creates a stoplist. |
DROP_INDEX_SET | Drops an index set. |
DROP_POLICY | Drops a policy. |
DROP_PREFERENCE | Deletes a preference from the Text data dictionary. |
DROP_SECTION_GROUP | Deletes a section group from the Text data dictionary. |
DROP_SHADOW_INDEX | Drops a shadow index. |
DROP_STOPLIST | Drops a stoplist. |
EXCHANGE_SHADOW_INDEX | Swaps the shadow index metadata and data. |
OPTIMIZE_INDEX | Optimizes the index. |
POPULATE_PENDING | Populates the pending queue with every rowid in the base table or table partition. |
RECREATE_INDEX_ONLINE | Recreates the passed-in index. |
REMOVE_INDEX | Removes an index from a CTXCAT index preference. |
REMOVE_MDATA | Removes MDATA values from a document. |
REMOVE_SECTION | Deletes a section from a section group. |
REMOVE_STOPCLASS | Deletes a stopclass from a stoplist. |
REMOVE_STOPTHEME | Deletes a stoptheme from a stoplist. |
REMOVE_STOPWORD | Deletes a stopword from a stoplist. |
REMOVE_SUB_LEXER | Deletes a sub-lexer from a multi-lexer preference. |
REPLACE_INDEX_METADATA | Replaces metadata for local domain indexes. |
SET_ATTRIBUTE | Sets a preference attribute. |
SYNC_INDEX | Synchronizes the index. |
UNSET_ATTRIBUTE | Removes a set attribute from a preference. |
UPDATE_POLICY | Updates a policy. |
Adds an attribute section to an XML section group. This procedure is useful for defining attributes in XML documents as sections. This enables you to search XML attribute text with the WITHIN
operator.
Note:
When you useAUTO_SECTION_GROUP
, attribute sections are created automatically. Attribute sections created automatically are named in the form tag@attribute
.CTX_DDL.ADD_ATTR_SECTION( group_name in varchar2, section_name in varchar2, tag in varchar2);
Specify the name of the XML section group. You can add attribute sections only to XML section groups.
Specify the name of the attribute section. This is the name used for WITHIN
queries on the attribute text.
The section name you specify cannot contain the colon (:), comma (,), or dot (.) characters. The section name must also be unique within group_name
. Section names are case-insensitive.
Attribute section names can be no more than 64 bytes long.
Specify the name of the attribute in tag@attr form. This parameter is case-sensitive.
Consider an XML file that defines the BOOK
tag with a TITLE
attribute as follows:
<BOOK TITLE="Tale of Two Cities"> It was the best of times. </BOOK>
To define the title attribute as an attribute section, create an XML_SECTION_GROUP
and define the attribute section as follows:
begin ctx_ddl.create_section_group('myxmlgroup', 'XML_SECTION_GROUP'); ctx_ddl.add_attr_section('myxmlgroup', 'booktitle', 'BOOK@TITLE'); end;
When you define the TITLE
attribute section as such and index the document set, you can query the XML attribute text as follows:
'Cities within booktitle'
Creates a field section and adds the section to an existing section group. This enables field section searching with the WITHIN operator.
Field sections are delimited by start and end tags. By default, the text within field sections are indexed as a sub-document separate from the rest of the document.
Unlike zone sections, field sections cannot nest or overlap. As such, field sections are best suited for non-repeating, non-overlapping sections such as TITLE
and AUTHOR
markup in e-mail- or news-type documents.
Because of how field sections are indexed, WITHIN queries on field sections are usually faster than WITHIN
queries on zone sections.
CTX_DDL.ADD_FIELD_SECTION( group_name in varchar2, section_name in varchar2, tag in varchar2, visible in boolean default FALSE );
Specify the name of the section group to which section_name
is added. You can add up to 64 field sections to a single section group. Within the same group, section zone names and section field names cannot be the same.
Specify the name of the section to add to the group_name
. Use this name to identify the section in queries. Avoid using names that contain non-alphanumeric characters such as _, because these characters must be escaped in queries. Section names are case-insensitive.
Within the same group, zone section names and field section names cannot be the same. The terms Paragraph and Sentence are reserved for special sections.
Section names need not be unique across tags. You can assign the same section name to more than one tag, which makes details transparent to searches.
Specify the tag that marks the start of a section. For example, if the tag is <H1>, then specify H1. The start tag you specify must be unique within a section group.
If group_name
is an HTML_SECTION_GROUP
, then you can create field sections for the META tag's NAME/CONTENT
attribute pairs. To do so, specify tag
as meta@namevalue
where namevalue
is the value of the NAME
attribute whose CONTENT
attribute is to be indexed as a section. Refer to the example "Creating Sections for <META>
Tags".
Oracle Text knows what the end tags look like from the group_type
parameter you specify when you create the section group.
Specify TRUE
to make the text visible within the rest of the document.
By default the visible
flag is FALSE
. This means that Oracle Text indexes the text within field sections as a sub-document separate from the rest of the document. However, you can set the visible flag to TRUE
if you want text within the field section to be indexed as part of the enclosing document.
Visible and Invisible Field Sections
The following example defines a section group basicgroup
of the BASIC_SECTION_GROUP
type. It then creates a field section in basicgroup
called Author
for the <A>
tag. It also sets the visible flag to FALSE
:
begin
ctx_ddl.create_section_group('basicgroup', 'BASIC_SECTION_GROUP'); ctx_ddl.add_field_section('basicgroup', 'Author', 'A', FALSE);
end;
Because the Author
field section is not visible, to find text within the Author
section, you must use the WITHIN operator as follows:
'(Martin Luther King) WITHIN Author'
A query of Martin Luther King without the WITHIN
operator does not return instances of this term in field sections. To query text within field sections without specifying WITHIN
, you must set the visible flag to TRUE
when you create the section as follows:
begin ctx_ddl.add_field_section('basicgroup', 'Author', 'A', TRUE); end;
Creating Sections for <META>
Tags
When you use the HTML_SECTION_GROUP
, you can create sections for META
tags.
Consider an HTML document that has a META
tag as follows:
<META NAME="author" CONTENT="ken">
To create a field section that indexes the CONTENT
attribute for the <META NAME="author">
tag:
begin ctx_ddl.create_section_group('myhtmlgroup', 'HTML_SECTION_GROUP'); ctx_ddl.add_field_section('myhtmlgroup', 'author', 'META@AUTHOR'); end
After indexing with section group mygroup
, query the document as follows:
'ken WITHIN author'
Field sections cannot be nested. For example, if you define a field section to start with <TITLE>
and define another field section to start with <FOO>
, the two sections cannot be nested as follows:
<TITLE> dog <FOO> cat </FOO> </TITLE>
To work with nested section define them as zone sections.
Repeated field sections are allowed, but WITHIN
queries treat them as a single section. The following is an example of repeated field section in a document:
<TITLE> cat </TITLE> <TITLE> dog </TITLE>
The query (dog and cat) within title returns the document, even though these words occur in different sections.
To have WITHIN
queries distinguish repeated sections, define them as zone sections.
Use this procedure to add a sub-index to a catalog index preference. Create this preference by naming one or more columns in the base table.
Because you create sub-indexes to improve the response time of structured queries, the column you add should be used in the structured_query
clause of the CATSEARCH
operator at query time.
CTX_DDL.ADD_INDEX(set_name in varchar2,
column_list varchar2, storage_clause varchar2);
Specify the name of the index set.
Specify a comma separated list of columns to index. At index time, any column listed here cannot have a NULL value in any row in the base table. If any row is NULL during indexing, then an error is raised.
Always ensure that your columns have non-NULL values before and after indexing.
Specify a storage clause.
Consider a table called AUCTION
with the following schema:
create table auction(
item_id number, title varchar2(100), category_id number, price number, bid_close date);
Assume that queries on the table involve a mandatory text query clause and optional structured conditions on category_id
. Results must be sorted based on bid_close
.
You can create a catalog index to support the different types of structured queries a user might enter.
To create the indexes, first create the index set preference then add the required indexes to it:
begin ctx_ddl.create_index_set('auction_iset'); ctx_ddl.add_index('auction_iset','bid_close'); ctx_ddl.add_index('auction_iset','category_id, bid_close'); end;
Create the combined catalog index with CREATE
INDEX
as follows:
create index auction_titlex on AUCTION(title) indextype is CTXCAT parameters ('index set auction_iset');
To query the title column for the word pokemon, enter regular and mixed queries as follows:
select * from AUCTION where CATSEARCH(title, 'pokemon',NULL)> 0; select * from AUCTION where CATSEARCH(title, 'pokemon', 'category_id=99 order by bid_close desc')> 0;
Use this procedure to change the metadata of a document that has been specified as an MDATA
section. After this call, MDATA
queries involving the named MDATA
value will find documents with the given MDATA
value.
There are two versions of CTX_DDL.ADD_MDATA
: one for adding a single metadata value to a single rowid, and one for handing multiple values, multiple rowids, or both.
CTX_DDL.ADD_MDATA
is transactional; it takes effect immediately in the calling session, can be seen only in the calling session, can be reversed with a ROLLBACK
command, and must be committed to take permanent effect.
Use CTX_DDL.REMOVE_MDATA to remove metadata values from already-indexed documents. Only the owner of the index is allowed to call ADD_MDATA
and REMOVE_MDATA
.
This is the syntax for adding a single value to a single rowid:
CTX_DDL.ADD_MDATA( idx_name IN VARCHAR2, section_name IN VARCHAR2, mdata_value IN VARCHAR2, mdata_rowid IN VARCHAR2, [part_name] IN VARCHAR2] );
Name of the text index that contains the named rowid.
Name of the MDATA
section.
The metadata value to add to the document.
The rowid to which to add the metadata value.
Name of the index partition, if any. Must be provided for local partitioned indexes and must be NULL for global, non-partitioned indexes.
This is the syntax for handling multiple values, multiple rowids, or both. This version is more efficient for large numbers of new values or rowids.
CTX_DDL.ADD_MDATA( idx_name IN VARCHAR2, section_name IN VARCHAR2, mdata_values SYS.ODCIVARCHAR2LIST, mdata_rowids SYS.ODCIRIDLIST, [part_name] IN VARCHAR2] );
Name of the text index that contains the named rowids.
Name of the MDATA
section.
List of metadata values. If a metadata value contains a comma, the comma must be escaped with a backslash.
The rowids to which to add the metadata values.
Name of the index partition, if any. Must be provided for local partitioned indexes and must be NULL for global, non-partitioned indexes.
This example updates a single value:
select rowid from mytab where contains(text, 'MDATA(sec, value')>0; No rows returned exec ctx_ddl.add_mdata('my_index', 'sec', 'value', 'ABC'); select rowid from mytab where contains(text, 'MDATA(sec, value')>0; ROWID ----- ABC
This example updates multiple values:
begin ctx_ddl.add_mdata('my_index', 'sec', sys.odcivarchar2list('value1','value2','value3'), sys.odciridlist('ABC','DEF')); end;
This is equivalent to:
begin ctx_ddl.add_mdata('my_index', 'sec', 'value1', 'ABC'); ctx_ddl.add_mdata('my_index', 'sec', 'value1', 'DEF'); ctx_ddl.add_mdata('my_index', 'sec', 'value2', 'ABC'); ctx_ddl.add_mdata('my_index', 'sec', 'value2', 'DEF'); ctx_ddl.add_mdata('my_index', 'sec', 'value3', 'ABC'); ctx_ddl.add_mdata('my_index', 'sec', 'value3', 'DEF'); end;
If a rowid is not yet indexed, CTX_DDL.ADD.MDATA
completes without error, but an error is logged in CTX_USER_INDEX_ERRORS
.
These updates are updates directly on the index itself, not on the actual contents stored in the base table. Therefore, they will not survive when the Text index is rebuilt.
See also "ADD_MDATA_SECTION"; "REMOVE_MDATA"; "MDATA"; as well as the Section Searching chapter of the Oracle Text Application Developer's Guide.
Use this procedure to map the FILTER
BY
column named in column_name to the MDATA
section named in section_name.
The syntax is as follows:
CTX_DDL.ADD_MDATA_COLUMN( group_name IN VARCHAR2, section_name IN VARCHAR2, column_name IN VARCHAR2, );
Name of the group that contains the section.
Name of the MDATA
section.
Name of the FILTER
BY
column to add to the MDATA
section.
MDATA
sections that are created with CTX_DDL.ADD_MDATA_COLUMN
cannot have their values changed using CTX_DDL.ADD_MDATA
or CTX_DDL.REMOVE_MDATA
. Doing so will result in errors being returned. The section values must be updated using SQL.
The stored datatype for MDATA
sections is text
. Therefore, the value of the FILTER
BY
column is converted to text
during indexing. For non-text datatypes, the FILTER
BY
columns are normalized to an internal format during indexing. If the section is queried with an MDATA
operator, then the MDATA
query string will also be normalized to the internal format before processing.
When a FILTER
BY
column is mapped as MDATA
, the cost-based optimizer in Oracle Text tries to avoid using the Oracle Text composite domain index to process range predicate(s) on that FILTER
BY
column. This is because range predicates on MDATA
FILTER
BY
columns are processed less efficiently than if they were declared as SDATA
. For this reason, you should not add a FILTER
BY
column as MDATA
if you plan to do range searches on the column.
See Also:
Chapter 8, "Searching Document Sections in Oracle Text" in Oracle Text Application Developer's GuideUse this procedure to add an MDATA
section, with an accompanying value, to an existing section group. MDATA
sections cannot be added to Null Section groups, Path Section groups, or Auto Section groups.
Section values undergo a simplified normalization:
Leading and trailing whitespace on the value is removed.
The value is truncated to 64 bytes.
The value is indexed as a single value; if the value consists of multiple words, it is not broken up.
Case is preserved. If the document is dynamically generated, then implement case-insensitivity by uppercasing MDATA
values and making sure to search only in uppercase.
Use CTX_DDL.REMOVE_SECTION to remove sections.
CTX_DDL.ADD_MDATA_SECTION( group_name IN VARCHAR2, section_name IN VARCHAR2, tag IN VARCHAR2, );
Name of the section group that will contain the MDATA
section.
Name of the MDATA
section.
The value of the MDATA
section. For example, if the section is <AUTHOR>
, the value could be Cynthia Kadohata (author of the novel The Floating World). More than one tag can be assigned to a given MDATA
section.
This example creates an MDATA
section called auth
.
ctx_ddl.create_section_group('htmgroup', 'HTML_SECTION_GROUP'); ctx_ddl.add_mdata_section('htmgroup', 'auth', 'author');
The Section Searching chapter of the Oracle Text Application Developer's Guide
Use this procedure to find matches that are spelled in a similar way. The value of an NDATA
section is extracted from the document text like other sections, but is indexed as name data. NDATA
sections are stored in the CTX_USER_SECTIONS
view.
CTX_DDL.ADD_NDATA_SECTION ( group_name IN VARCHAR2, section_name IN VARCHAR2, tag IN VARCHAR2);
Name of the group that contains the section.
Name of the NDATA
section.
Name of the tag that marks the start of a section. For example, if the tag is <H1>, specify H1. The start tag you specify must be unique within a section group.
NDATA
sections support both single and multi-byte data, however, there are character- and term-based limitations. NDATA
section data that is indexed is constrained as follows:
number of characters in a single, white space delimited term
511
number of white space delimited terms
255
total number of characters, including white spaces
511
NDATA
section data that exceeds these constraints are truncated.
The following example defines a section group namegroup
of the BASIC_SECTION_GROUP
type. It then creates an NDATA
section in namegroup
called firstname
.
begin ctx_ddl.create_section_group('namegroup', 'BASIC_SECTION_GROUP'); ctx_ddl.add_ndata_section('namegroup', 'firstname', 'fname1'); end;
Use this procedure to map the FILTER
BY
or ORDER
BY
column named in column_name to the SDATA
section named in section_name. By default, all FILTER
BY
columns are mapped as SDATA
.
The syntax is as follows:
CTX_DDL.ADD_SDATA_COLUMN( group_name IN VARCHAR2, section_name IN VARCHAR2, column_name IN VARCHAR2, );
Name of the group that contains the section.
Name of the SDATA
section.
Name of the FILTER
BY
column to add to the SDATA
section.
Mapping FILTER
BY
columns to sections is optional. If no section mapping exists for a FILTER
BY
column, then it is mapped to an SDATA
section, and the section name will be the name of the FILTER
BY
column.
If a section group is not specified during CREATE
INDEX
of a composite domain index, then system default section group settings will be used, and a SDATA
section will be created for each of the FILTER
BY
and ORDER
BY
columns.
Note:
Because section name does not allow certain special characters and is case insensitive, if the column name is case sensitive or contains special characters, then an error will be raised. To work around this problem, you need to map the column to anMDATA
or SDATA
section before creating the index. Refer to CTX_DDL.ADD_MDATA_COLUMN or CTX_DDL.ADD_SDATA_COLUMN in this chapter.An error will be raised if a column mapped to MDATA
also appears in the ORDER
BY
column clause.
Column section names are unique to their section group. That is, you cannot have an MDATA
column section named FOO
if you already have an MDATA
column section named FOO
. Furthermore, you cannot have a field section named FOO
if you already have an SDATA
column section named FOO
. This is true whether it is implicitly created (by CREATE
INDEX
for FILTER
BY
or ORDER
BY
clauses) or explicitly created (by CTX_DDL.ADD_SDATA_COLUMN
).
One section name can only be mapped to one FILTER
BY
column, and vice versa. For example, mapping a section to more than one column or mapping a column to more than one section is not allowed.
Column sections can be added to any type of section group, including the NULL
section group.
32 is the maximum number for SDATA
sections and columns.
See Also:
Chapter 8, "Searching Document Sections in Oracle Text" in Oracle Text Application Developer's GuideThis procedure adds an SDATA
section to a section group. By default, all FILTER
BY
columns are mapped as SDATA
.
The syntax is as follows:
CTX_DDL.ADD_SDATA_SECTION( group_name IN VARCHAR2, section_name IN VARCHAR2, tag IN VARCHAR2, datatype IN VARCHAR2, default NULL, );
Name of the group that contains the section.
Name of the SDATA
section.
Name of the tag to add to the SDATA
section.
Specifies the stored format for the data, as well as the semantics of comparison in later use in SDATA
operators. The default is VARCHAR2
, but if specified must be one of the following values:
VARCHAR2
CHAR
RAW
NUMBER
DATE
The VARCHAR2
datatype stores up to 249 bytes of character data in the database character set. Values larger than this result in a per-document indexing error. Note that leading and trailing whitespace are always trimmed from SDATA
section values when extracted by the sectioner. This is different than SDATA
columns. Column values are never trimmed. No lexing is performed on the value from either kind of SDATA
.
The CHAR
datatype stores up to 249 bytes of character data in the database character set. Values larger than this result in a per-document indexing error. Note that leading and trailing whitespace are always trimmed from SDATA
section values when extracted by the sectioner. This is different than SDATA
columns. Column values are never trimmed. No lexing is performed on the value from either kind of SDATA
. To be consistent with SQL, the comparisons of CHAR
datatype SDATA
values are blank-padded comparisons.
RAW
datatype stores up to 249 bytes of binary data. Values larger than this result in a per-document indexing error. The value is converted from hexadecimal string representation. That is, to store a value of 65
, the document should look like <TAG>40</TAG>
, and not <TAG>65</TAG>
or <TAG>A</TAG>
.
The DATE
datatype values must conform to the following format: YYYY-MM-DD
or YYYY-MM-DD HH24:MI:SS
. That is, to store a DATE
value of "Nov. 24, 2006 10:32pm 36sec", the document should look like <TAG>2006-11-24 22:32:36</TAG>
.
SDATA
are single-occurrence only. If multiple instances of an SDATA
tag are encountered in a single document, then later instances supersede the value set by earlier instances. This means that the last occurrence of an SDATA
tag takes effect.
If no SDATA
tag occurs in a given document, then this is treated as an SDATA
value of NULL
.
Empty SDATA
tags are treated as NULL
values.
SDATA
sections cannot be nested. Sections that are nested inside are ignored.
32 is the maximum number for SDATA
sections and columns.
See Also:
Chapter 8, "Searching Document Sections in Oracle Text" in Oracle Text Application Developer's GuideAdds a special section, either SENTENCE
or PARAGRAPH
, to a section group. This enables searching within sentences or paragraphs in documents with the WITHIN operator.
A special section in a document is a section which is not explicitly tagged like zone and field sections. The start and end of special sections are detected when the index is created. Oracle Text supports two such sections: paragraph and sentence.
The sentence and paragraph boundaries are determined by the lexer. For example, the lexer recognizes sentence and paragraph section boundaries as follows:
Table 7-1 Paragraph and Sentence Section Boundaries
Special Section | Boundary |
---|---|
SENTENCE |
WORD/PUNCT/WHITESPACE |
WORD/PUNCT/NEWLINE |
|
PARAGRAPH |
WORD/PUNCT/NEWLINE/WHITESPACE (indented paragraph) |
WORD/PUNCT/NEWLINE/NEWLINE (block paragraph) |
The punctuation, whitespace, and newline characters are determined by your lexer settings and can be changed.
If the lexer cannot recognize the boundaries, no sentence or paragraph sections are indexed.
CTX_DDL.ADD_SPECIAL_SECTION( group_name IN VARCHAR2, section_name IN VARCHAR2);
Specify the name of the section group.
Specify SENTENCE
or PARAGRAPH
.
The following example enables searching within sentences within HTML documents:
begin ctx_ddl.create_section_group('htmgroup', 'HTML_SECTION_GROUP'); ctx_ddl.add_special_section('htmgroup', 'SENTENCE'); end;
Add zone sections to the group to enable zone searching in addition to sentence searching. The following example adds the zone section Headline
to the section group htmgroup
:
begin ctx_ddl.create_section_group('htmgroup', 'HTML_SECTION_GROUP'); ctx_ddl.add_special_section('htmgroup', 'SENTENCE'); ctx_ddl.add_zone_section('htmgroup', 'Headline', 'H1'); end;
If you are only interested in sentence or paragraph searching within documents and not interested in defining zone or field sections, then use the NULL_SECTION_GROUP
as follows:
begin ctx_ddl.create_section_group('nullgroup', 'NULL_SECTION_GROUP'); ctx_ddl.add_special_section('nullgroup', 'SENTENCE'); end;
Adds a stopclass to a stoplist. A stopclass is a class of tokens that is not to be indexed.
CTX_DDL.ADD_STOPCLASS( stoplist_name in varchar2, stopclass in varchar2 );
Specify the name of the stoplist.
Specify the stopclass to be added to stoplist_name
. Currently, only the NUMBERS
class is supported. It is not possible to create a custom stopclass.
NUMBERS
includes tokens that follow the number pattern: digits, numgroup
, and numjoin
only. Therefore, 123ABC is not a number, nor is A123. These are labeled as MIXED
. $123 is not a number (this token is not common in a text index because non-alphanumerics become whitespace by default). In the United States, 123.45 is a number, but 123.456.789 is not; in Europe, where numgroup may be '.', the reverse is true.
The maximum number of stopwords, stopthemes, and stopclasses you can add to a stoplist is 4095.
The following example adds a stopclass of NUMBERS
to the stoplist mystop
:
begin ctx_ddl.add_stopclass('mystop', 'NUMBERS'); end;
Adds a stop section to an automatic section group. Adding a stop section causes the automatic section indexing operation to ignore the specified section in XML documents.
Note:
Adding a stop section causes no section information to be created in the index. However, the text within a stop section is always searchable.Adding a stop section is useful when your documents contain many low information tags. Adding stop sections also improves indexing performance with the automatic section group.
The number of stop sections you can add is unlimited.
Stop sections do not have section names and hence are not recorded in the section views.
CTX_DDL.ADD_STOP_SECTION( section_group IN VARCHAR2, tag IN VARCHAR2);
Specify the name of the automatic section group. If you do not specify an automatic section group, then this procedure returns an error.
Specify the tag to ignore during indexing. This parameter is case-sensitive. Defining a stop tag as such also stops the tag's attribute sections, if any.
Qualify the tag with document type in the form (doctype)tag
. For example, if you wanted to make the <fluff>
tag a stop section only within the mydoc
document type, specify (mydoc)fluff
for tag.
The following example adds a stop section identified by the tag <fluff>
to the automatic section group myauto
:
begin ctx_ddl.add_stop_section('myauto', 'fluff'); end;
This example also stops any attribute sections contained within <fluff>
. For example, if a document contained:
<fluff type="computer">
Then the preceding example also stops the attribute section fluff@type.
Doctype Sensitive Stop Sections
The following example creates a stop section for the tag <fluff>
only in documents that have a root element of mydoc
:
begin ctx_ddl.add_stop_section('myauto', '(mydoc)fluff'); end;
Adds a single stoptheme to a stoplist. A stoptheme is a theme that is not to be indexed.
In English, query on indexed themes using the ABOUT operator.
CTX_DDL.ADD_STOPTHEME( stoplist_name in varchar2, stoptheme in varchar2 );
Specify the name of the stoplist.
Specify the stoptheme to be added to stoplist_name
. The system normalizes the stoptheme
you enter using the knowledge base. If the normalized theme is more than one theme, then the system does not process your stoptheme. For this reason, Oracle recommends that you submit single stopthemes.
The maximum number of stopwords, stopthemes, and stopclasses you can add to a stoplist is 4095.
The following example adds the stoptheme banking
to the stoplist mystop
:
begin ctx_ddl.add_stoptheme('mystop', 'banking'); end;
Use this procedure to add a single stopword to a stoplist.
To create a list of stopwords, you must call this procedure once for each word.
CTX_DDL.ADD_STOPWORD(
stoplist_name in varchar2, stopword in varchar2, language in varchar2 default NULL
);
Specify the name of the stoplist.
Specify the stopword to be added.
Language-specific stopwords must be unique across the other stopwords specific to the language. For example, it is valid to have a German die and an English die in the same stoplist.
The maximum number of stopwords, stopthemes, and stopclasses you can add to a stoplist is 4095.
Specify the language of stopword
when the stoplist you specify with stoplist_name
is of type MULTI_STOPLIST
. You must specify the globalization support name or abbreviation of an Oracle Text-supported language.
To make a stopword active in multiple languages, specify ALL
for this parameter. For example, defining ALL
stopwords is useful when you have international documents that contain English fragments that need to be stopped in any language.
An ALL
stopword is active in all languages. If you use the multi-lexer, the language-specific lexing of the stopword occurs, just as if it had been added multiple times in multiple specific languages.
Otherwise, specify NULL
.
The following example adds the stopwords because, notwithstanding, nonetheless, and therefore to the stoplist mystop
:
begin
ctx_ddl.add_stopword('mystop', 'because'); ctx_ddl.add_stopword('mystop', 'notwithstanding'); ctx_ddl.add_stopword('mystop', 'nonetheless'); ctx_ddl.add_stopword('mystop', 'therefore');
end;
The following example adds the German word die to a multi-language stoplist:
begin
ctx_ddl.add_stopword('mystop', 'Die','german');
end;
Note:
Add stopwords after you create the index withALTER
INDEX
.The following adds the word the as an ALL
stopword to the multi-language stoplist globallist:
begin
ctx_ddl.add_stopword('globallist','the','ALL');
end;
Add a sub-lexer to a multi-lexer preference. A sub-lexer identifies a language in a multi-lexer (multi-language) preference. Use a multi-lexer preference when you want to index more than one language.
The following restrictions apply to using CTX_DDL.ADD_SUB_LEXER
:
The invoking user must be the owner of the multi-lexer or CTXSYS
.
The lexer_name parameter must name a preference which is a multi-lexer lexer.
A lexer for default must be defined before the multi-lexer can be used in an index.
The sub-lexer preference owner must be the same as multi-lexer preference owner.
The sub-lexer preference must not be a multi-lexer lexer.
A sub-lexer preference cannot be dropped while it is being used in a multi-lexer preference.
CTX_DDL.ADD_SUB_LEXER
records only a reference. The sub-lexer values are copied at create index time to index value storage.
CTX_DDL.ADD_SUB_LEXER( lexer_name in varchar2, language in varchar2, sub_lexer in varchar2, alt_value in varchar2 default null );
Specify the name of the multi-lexer preference.
Specify the globalization support language name or abbreviation of the sub-lexer. For example, specify JAPANESE
or JA
for Japanese.
The sub-lexer you specify with sub_lexer
is used when the language column has a value case-insensitive equal to the globalization support name of abbreviation of language
.
Specify DEFAULT
to assign a default sub-lexer to use when the value of the language column in the base table is null, invalid, or unmapped to a sub-lexer. The DEFAULT
lexer is also used to parse stopwords.
If a sub-lexer definition for language
already exists, then it is replaced by this call.
Specify the name of the sub-lexer to use for this language.
Optionally specify an alternate value for language
.
If you specify DEFAULT
for language
, then you cannot specify an alt_value
.
The alt_value
is limited to 30 bytes and cannot be a globalization support language name, abbreviation, or DEFAULT
.
This example shows how to create a multi-language text table and how to set up the multi-lexer to index the table.
Create the multi-language table with a primary key, a text column, and a language column as follows:
create table globaldoc ( doc_id number primary key, lang varchar2(3), text clob );
Assume that the table holds mostly English documents, with an occasional German or Japanese document. To handle the three languages, you must create three sub-lexers: one for English, one for German, and one for Japanese as follows:
ctx_ddl.create_preference('english_lexer','basic_lexer'); ctx_ddl.set_attribute('english_lexer','index_themes','yes'); ctx_ddl.set_attribtue('english_lexer','theme_language','english'); ctx_ddl.create_preference('german_lexer','basic_lexer'); ctx_ddl.set_attribute('german_lexer','composite','german'); ctx_ddl.set_attribute('german_lexer','mixed_case','yes'); ctx_ddl.set_attribute('german_lexer','alternate_spelling','german'); ctx_ddl.create_preference('japanese_lexer','japanese_vgram_lexer');
Create the multi-lexer preference:
ctx_ddl.create_preference('global_lexer', 'multi_lexer');
Because the stored documents are mostly English, make the English lexer the default:
ctx_ddl.add_sub_lexer('global_lexer','default','english_lexer');
Add the German and Japanese lexers in their respective languages. Also assume that the language column is expressed in ISO 639-2, so add those as alternative values.
ctx_ddl.add_sub_lexer('global_lexer','german','german_lexer','ger'); ctx_ddl.add_sub_lexer('global_lexer','japanese','japanese_lexer','jpn');
Create the index globalx
, specifying the multi-lexer preference and the language column in the parameters string as follows:
create index globalx on globaldoc(text) indextype is ctxsys.context parameters ('lexer global_lexer language column lang');
Creates a zone section and adds the section to an existing section group. This enables zone section searching with the WITHIN operator.
Zone sections are sections delimited by start and end tags. The <B>
and </B>
tags in HTML, for instance, marks a range of words which are to be rendered in boldface.
Zone sections can be nested within one another, can overlap, and can occur more than once in a document.
CTX_DDL.ADD_ZONE_SECTION( group_name in varchar2, section_name in varchar2, tag in varchar2 );
Specify the name of the section group to which section_name
is added.
Specify the name of the section to add to the group_name. Use this name to identify the section in WITHIN
queries. Avoid using names that contain non-alphanumeric characters such as _, because most of these characters are special must be escaped in queries. Section names are case-insensitive.
Within the same group, zone section names and field section names cannot be the same. The terms Paragraph and Sentence are reserved for special sections.
Section names need not be unique across tags. You can assign the same section name to more than one tag, making details transparent to searches.
Specify the pattern which marks the start of a section. For example, if <H1>
is the HTML tag, specify H1
for tag
. The start tag you specify must be unique within a section group.
Oracle Text knows what the end tags look like from the group_type
parameter you specify when you create the section group.
If group_name
is an HTML_SECTION_GROUP
, you can create zone sections for the META tag's NAME/CONTENT
attribute pairs. To do so, specify tag
as meta@namevalue
where namevalue
is the value of the NAME
attribute whose CONTENT
attributes are to be indexed as a section. Refer to the example.
If group_name
is an XML_SECTION_GROUP
, you can optionally qualify tag
with a document type (root element) in the form (doctype)tag
. Doing so makes section_name
sensitive to the XML document type declaration. Refer to the example.
The following example defines a section group called htmgroup
of type HTML_SECTION_GROUP
. It then creates a zone section in htmgroup
called headline
identified by the <H1> tag:
begin ctx_ddl.create_section_group('htmgroup', 'HTML_SECTION_GROUP'); ctx_ddl.add_zone_section('htmgroup', 'heading', 'H1'); end;
After indexing with section group htmgroup
, query within the heading section by issuing a query as follows:
'Oracle WITHIN heading'
Creating Sections for <META NAME>
Tags
You can create zone sections for HTML META tags when you use the HTML_SECTION_GROUP
.
Consider an HTML document that has a META
tag as follows:
<META NAME="author" CONTENT="ken">
To create a zone section that indexes all CONTENT
attributes for the META
tag whose NAME
value is author:
begin ctx_ddl.create_section_group('htmgroup', 'HTML_SECTION_GROUP'); ctx_ddl.add_zone_section('htmgroup', 'author', 'meta@author'); end
After indexing with section group htmgroup
, query the document as follows:
'ken WITHIN author'
Creating Document Type Sensitive Sections (XML Documents Only)
You have an XML document set that contains the <book>
tag declared for different document types (DTDs). You want to create a distinct book section for each document type.
Assume that myDTDname
is declared as an XML document type as follows:
<!DOCTYPE myDTDname> <myDTDname> ...
(Note: the DOCTYPE
must match the top-level tag.)
Within myDTDname
, the element <book>
is declared. For this tag, create a section named mybooksec
that is sensitive to the tag's document type as follows:
begin ctx_ddl.create_section_group('myxmlgroup', 'XML_SECTION_GROUP'); ctx_ddl.add_zone_section('myxmlgroup', 'mybooksec', '(myDTDname)book'); end;
Zone sections can repeat. Each occurrence is treated as a separate section. For example, if <H1> denotes a heading
section, they can repeat in the same documents as follows:
<H1> The Brown Fox </H1>
<H1> The Gray Wolf </H1>
Assuming that these zone sections are named Heading
, the query Brown WITHIN Heading returns this document. However, a query of (Brown and Gray) WITHIN Heading does not.
Zone sections can overlap each other. For example, if <B>
and <I>
denote two different zone sections, they can overlap in document as follows:
plain <B> bold <I> bold and italic </B> only italic </I> plain
Zone sections can nest, including themselves as follows:
<TD> <TABLE><TD>nested cell</TD></TABLE></TD>
Using the WITHIN
operator, you can write queries to search for text in sections within sections. For example, assume the BOOK1
, BOOK2
, and AUTHOR
zone sections occur as follows in documents doc1 and doc2:
doc1:
<book1> <author>Scott Tiger</author> This is a cool book to read.</book1>
doc2:
<book2> <author>Scott Tiger</author> This is a great book to read.</book2>
Consider the nested query:
'(Scott within author) within book1'
This query returns only doc1.
Creates a new policy from an existing policy or index.
ctx_ddl.copy_policy( source_policy VARCHAR2, policy_name VARCHAR2 );
The name of the policy or index being copied.
The name of the new policy copy.
The preference values are copied from the source_policy
. Both the source policy or index and the new policy must be owned by the same database user.
Creates an index set for CTXCAT
index types. Name this index set in the parameter clause of CREATE
INDEX
when you create a CTXCAT
index.
Creates a policy to use with the CTX_DOC.POLICY_*
procedures and the ORA:CONTAINS
function. ORA:CONTAINS
is a function you use within an XPATH
query expression with existsNode()
.
See Also:
Oracle XML DB Developer's GuideCTX_DDL.CREATE_POLICY( policy_name IN VARCHAR2, filter IN VARCHAR2 DEFAULT NULL, section_group IN VARCHAR2 DEFAULT NULL, lexer IN VARCHAR2 DEFAULT NULL, stoplist IN VARCHAR2 DEFAULT NULL, wordlist IN VARCHAR2 DEFAULT NULL);
Specify the name for the new policy. Policy names and Text indexes share the same namespace.
Specify the filter preference to use.
Specify the section group to use. You can specify any section group that is supported by CONTEXT
index.
Specify the lexer preference to use. Your INDEX_THEMES
attribute must be disabled.
Specify the stoplist to use.
Specify the wordlist to use.
Create mylex lexer preference named mylex.
begin ctx_ddl.create_preference('mylex', 'BASIC_LEXER'); ctx_ddl.set_attribute('mylex', 'printjoins', '_-'); ctx_ddl.set_attribute ( 'mylex', 'index_themes', 'NO'); ctx_ddl.set_attribute ( 'mylex', 'index_text', 'YES'); end;
Create a stoplist preference named mystop.
begin ctx_ddl.create_stoplist('mystop', 'BASIC_STOPLIST'); ctx_ddl.add_stopword('mystop', 'because'); ctx_ddl.add_stopword('mystop', 'nonetheless'); ctx_ddl.add_stopword('mystop', 'therefore'); end;
Create a wordlist preference named 'mywordlist'.
begin ctx_ddl.create_preference('mywordlist', 'BASIC_WORDLIST'); ctx_ddl.set_attribute('mywordlist','FUZZY_MATCH','ENGLISH'); ctx_ddl.set_attribute('mywordlist','FUZZY_SCORE','0'); ctx_ddl.set_attribute('mywordlist','FUZZY_NUMRESULTS','5000'); ctx_ddl.set_attribute('mywordlist','SUBSTRING_INDEX','TRUE'); ctx_ddl.set_attribute('mywordlist','STEMMER','ENGLISH'); end;
exec ctx_ddl.create_policy('my_policy', NULL, NULL, 'mylex', 'mystop', 'mywordlist');
or
exec ctx_ddl.create_policy(policy_name => 'my_policy', lexer => 'mylex', stoplist => 'mystop', wordlist => 'mywordlist');
Then enter the following existsNode()
query with your own defined policy:
select id from xmltab where existsNode(doc, '/book/chapter[ ora:contains(summary,"dog or cat", "my_policy") >0 ]', 'xmlns:ora="http://xmlns.oracle.com/xdb" ')=1;
Update the policy with the following:
exec ctx_ddl.update_policy(policy_name => 'my_policy', lexer => 'my_new_lex');
Drop the policy with the following:
exec ctx_ddl.drop_policy(policy_name => 'my_policy');
Creates a preference in the Text data dictionary. Specify preferences in the parameter string of CREATE INDEX or ALTER INDEX.
Caution:
CTX_DDL.CREATE_PREFERENCE
does not respect the current schema as set by ALTER
SESSION
SET
current_schema
. Therefore, if you need to create or delete a preference owned by another user, then you must explicitly state this, and you must have the CREATE
ANY
TABLE
system privilege.CTX_DDL.CREATE_PREFERENCE(preference_name in varchar2, object_name in varchar2);
Specify the name of the preference to be created.
Specify the name of the preference type.
See Also:
For a complete list of preference types and their associated attributes, see Chapter 2, "Oracle Text Indexing Elements"The following example creates a lexer preference that specifies a text-only index. It does so by creating a BASIC_LEXER
preference called my_lexer
with CTX_DDL.CREATE_PREFERENCE
. It then calls CTX_DDL.SET_ATTRIBUTE twice, first specifying YES for the INDEX_TEXT
attribute, then specifying NO for the INDEX_THEMES
attribute.
begin ctx_ddl.create_preference('my_lexer', 'BASIC_LEXER'); ctx_ddl.set_attribute('my_lexer', 'INDEX_TEXT', 'YES'); ctx_ddl.set_attribute('my_lexer', 'INDEX_THEMES', 'NO'); end;
The following example creates a data storage preference called mypref
that tells the system that the files to be indexed are stored in the operating system. The example then uses CTX_DDL.SET_ATTRIBUTE to set the PATH
attribute of to the directory /docs
.
begin ctx_ddl.create_preference('mypref', 'FILE_DATASTORE'); ctx_ddl.set_attribute('mypref', 'PATH', '/docs'); end;
See Also:
For more information about data storage, see "Datastore Types"Creating Master/Detail Relationship
Use CTX_DDL.CREATE_PREFERENCE to create a preference with DETAIL_DATASTORE
. Use CTX_DDL.SET_ATTRIBUTE to set the attributes for this preference. The following example shows how this is done:
begin ctx_ddl.create_preference('my_detail_pref', 'DETAIL_DATASTORE'); ctx_ddl.set_attribute('my_detail_pref', 'binary', 'true'); ctx_ddl.set_attribute('my_detail_pref', 'detail_table', 'my_detail'); ctx_ddl.set_attribute('my_detail_pref', 'detail_key', 'article_id'); ctx_ddl.set_attribute('my_detail_pref', 'detail_lineno', 'seq'); ctx_ddl.set_attribute('my_detail_pref', 'detail_text', 'text'); end;
See Also:
For more information about master/detail, see "DETAIL_DATASTORE"The following examples specify that the index tables are to be created in the foo
tablespace with an initial extent of 1K:
begin ctx_ddl.create_preference('mystore', 'BASIC_STORAGE'); ctx_ddl.set_attribute('mystore', 'I_TABLE_CLAUSE', 'tablespace foo storage (initial 1K)'); ctx_ddl.set_attribute('mystore', 'K_TABLE_CLAUSE', 'tablespace foo storage (initial 1K)'); ctx_ddl.set_attribute('mystore', 'R_TABLE_CLAUSE', 'tablespace foo storage (initial 1K)'); ctx_ddl.set_attribute('mystore', 'S_TABLE_CLAUSE', 'tablespace foo storage (initial 1K)'); ctx_ddl.set_attribute('mystore', 'N_TABLE_CLAUSE', 'tablespace foo storage (initial 1K)'); ctx_ddl.set_attribute('mystore', 'I_INDEX_CLAUSE', 'tablespace foo storage (initial 1K)'); end;
See Also:
Storage TypesCreating Preferences with No Attributes
When you create preferences with types that have no attributes, you need only create the preference, as in the following example which sets the filter to the NULL_FILTER
:
begin ctx_ddl.create_preference('my_null_filter', 'NULL_FILTER'); end;
If s_table_clause
is specified for a storage preference in an index without SDATA
, then it has no effect on the index, and the index creation will still succeed.
Creates a section group for defining sections in a text column.
When you create a section group, you can add to it zone, field, or special sections with ADD_ZONE_SECTION, ADD_FIELD_SECTION, ADD_MDATA_SECTION, or ADD_SPECIAL_SECTION.
When you index, name the section group in the parameter string of CREATE INDEX or ALTER INDEX.
After indexing, query within your defined sections with the WITHIN operator.
CTX_DDL.CREATE_SECTION_GROUP( group_name in varchar2, group_type in varchar2 );
Specify the section group name to create as [user.]section_group_name
. This parameter must be unique within an owner.
Specify section group type. The group_type parameter can be one of:
The following command creates a section group called htmgroup
with the HTML group type.
begin
ctx_ddl.create_section_group('htmgroup', 'HTML_SECTION_GROUP');
end;
The following command creates a section group called auto
with the AUTO_SECTION_GROUP
group type to be used to automatically index tags in XML documents.
begin
ctx_ddl.create_section_group('auto', 'AUTO_SECTION_GROUP');
end;
Creates index metadata (or policy) for the specified index. If the index is not partitioned, then it also creates the index tables. This procedure is only supported in Enterprise Edition of Oracle Database.
The following changes are not supported:
Transition from non-composite domain index to composite, or changing the composite domain index columns.
Rebuild indexes that have partitioned index tables, for example, $I, $P, $K.
Note:
For a partitioned index, you must first call this procedure to create the shadow index metadata. This procedure will not create index tables. It has no effect on query, DML, sync, or optimize operations.CTX_DDL.CREATE_SHADOW_INDEX( idx_name IN VARCHAR2, parameter_string IN VARCHAR2 DEFAULT NULL, parallel_degree IN NUMBER, DEFAULT 1 );
The name of a valid CONTEXT
indextype.
For non-partitioned index, the same string as in ALTER
INDEX
. For partitioned index, the same string as in ALTER
INDEX
PARAMETER
.
Reserved for future use. Specify the degree of parallelism. Parallel operation is not currently supported.
Example 7-1 Scheduled Global Index Recreate (Incremental Rebuild)
In this example, you have the finest control over each stage of RECREATE_INDEX_ONLINE. Since SYNC_INDEX
can take a time limit, you can limit SYNC_INDEX
during non-business hours and incrementally recreate the index.
/* create lexer and original index */ exec ctx_ddl.create_preference('us_lexer','basic_lexer'); create index idx on tbl(text) indextype is ctxsys.context parameters('lexer us_lexer'); /* create a new lexer */ begin ctx_ddl.create_preference('e_lexer','basic_lexer'); ctx_ddl.set_attribute('e_lexer','base_letter','yes'); ctx_ddl.create_preference('m_lexer','multi_lexer'); ctx_ddl.add_sub_lexer('m_lexer','default','us_lexer'); ctx_ddl.add_sub_lexer('m_lexer','e','e_lexer'); end; / /* add new language column to the table for multi-lexer */ alter table tbl add(lang varchar2(10) default 'us'); /* create shadow index */ exec ctx_ddl.create_shadow_index('idx', 'replace lexer m_lexer language column lang NOPOPULATE'); declare idxid integer; begin /* figure out shadow index name */ select idx_id into idxid from ctx_user_indexes where idx_name ='IDX'; /* populate pending */ ctx_ddl.populate_pending('RIO$'||idxid); /* time limited sync */ ctx_ddl.sync_index(idx_name =>'RIO$'||idxid, maxtime =>480); /* more sync until no pending rows for the shadow index */ end; /* swap in the shadow index */ exec ctx_ddl.exchange_shadow_index('idx');
The index name for the shadow index is RIO$index_id
. By default it will also populate index tables for non-partitioned indexes, unless NOPOPULATE
is specified in CREATE
INDEX
or in ALTER
INDEX
. For a local partitioned index, it will only create index metadata without creating the index tables for each partition. Each index can have only one shadow index.
When building a non-partitioned index online, you can first call this procedure to create index metadata and index tables. If you specify POPULATE
, then this procedure will populate the index, but will not do swapping. You can schedule the swapping at a later, preferred time.
If you specify NOPOPULATE
, it will only create metadata for the index tables, but will not populate them. You must perform POPULATE_PENDING
(CTX_DDL.POPULATE_PENDING) to populate the pending queues after running this procedure, and then sync the indexes. This is referred to as incremental recreate.
Queries are all processed normally when this procedure is running.
If POPULATE
is specified, then DML is blocked for a very short time at the beginning of populate, after which all further DML is logged into an online pending queue and processed later.
Sync with CTX_DDL.SYNC_INDEX runs normally on the index. OPTIMIZE_INDEX runs without doing anything, but does not return an error.
See also POPULATE
| NOPOPULATE
in ALTER INDEX and CREATE INDEX in Chapter 1, "Oracle Text SQL Statements and Operators", and CTX_DDL.DROP_SHADOW_INDEX, CTX_DDL.EXCHANGE_SHADOW_INDEX, CTX_DDL.SYNC_INDEX, and CTX_DDL.POPULATE_PENDING in this chapter.
Use this procedure to create a new, empty stoplist. Stoplists can contain words or themes that are not to be indexed.
You can also create multi-language stoplists to hold language-specific stopwords. A multi-language stoplist is useful when you index a table that contains documents in different languages, such as English, German, and Japanese. When you do so, the text table must contain a language column.
Add either stopwords, stopclasses, or stopthemes to a stoplist using ADD_STOPWORD, ADD_STOPCLASS, or ADD_STOPTHEME. Specify a stoplist in the parameter string of CREATE INDEX or ALTER INDEX to override the default stoplist CTXSYS.DEFAULT_STOPLIST.
CTX_DDL.CREATE_STOPLIST(
stoplist_name IN VARCHAR2, stoplist_type IN VARCHAR2 DEFAULT 'BASIC_STOPLIST');
Specify the name of the stoplist to be created.
Specify BASIC_STOPLIST
to create a stoplist for a single language. This is the default.
Specify MULTI_STOPLIST
to create a stoplist with language-specific stopwords.
At indexing time, the language column of each document is examined, and only the stopwords for that language are eliminated. At query time, the session language setting determines the active stopwords, like it determines the active lexer when using the multi-lexer.
Note:
When indexing a multi-language table with a multi-language stoplist, the table must have a language column.Example 7-2 Single Language Stoplist
The following example creates a stoplist called mystop
:
begin ctx_ddl.create_stoplist('mystop', 'BASIC_STOPLIST'); end;
Example 7-3 Multi-Language Stoplist
The following example creates a multi-language stoplist called multistop
and then adds tow language-specific stopwords:
begin ctx_ddl.create_stoplist('multistop', 'MULTI_STOPLIST'); ctx_ddl.add_stopword('mystop', 'Die','german'); ctx_ddl.add_stopword('mystop', 'Or','english'); end;
Drops a CTXCAT
index set created with CTX_DDL.CREATE_INDEX_SET.
Drops a policy created with CTX_DDL.CREATE_POLICY.
The DROP_PREFERENCE
procedure deletes the specified preference from the Text data dictionary. Dropping a preference does not affect indexes that have already been created using that preference.
CTX_DDL.DROP_PREFERENCE( preference_name IN VARCHAR2 );
Specify the name of the preference to be dropped.
The following example drops the preference my_lexer
.
begin ctx_ddl.drop_preference('my_lexer'); end;
See also CTX_DDL.CREATE_PREFERENCE.
The DROP_SECTION_GROUP
procedure deletes the specified section group, as well as all the sections in the group, from the Text data dictionary.
CTX_DDL.DROP_SECTION_GROUP( group_name IN VARCHAR2 );
Specify the name of the section group to delete.
The following example drops the section group htmgroup
and all its sections:
begin ctx_ddl.drop_section_group('htmgroup'); end;
See also CTX_DDL.CREATE_SECTION_GROUP.
Drops a shadow index for the specified index. When you drop a shadow index, if it is partitioned, then its metadata and the metadata of all this shadow index's partitions are dropped. This procedure also drops all the shadow index tables and cleans up any online pending queue.
CTX_DDL.DROP_SHADOW_INDEX( idx_name in VARCHAR2 );
The name of a valid CONTEXT
indextype.
The following example drops the shadow index myshadowidx
:
begin ctx_ddl.drop_shadow_index('myshadowidx'); end;
See also CTX_DDL.CREATE_SHADOW_INDEX.
Drops a stoplist from the Text data dictionary. When you drop a stoplist, you must re-create or rebuild the index for the change to take effect.
CTX_DDL.DROP_STOPLIST(stoplist_name in varchar2);
Specify the name of the stoplist.
The following example drops the stoplist mystop
:
begin ctx_ddl.drop_stoplist('mystop'); end;
See also CTX_DDL.CREATE_STOPLIST.
This procedure swaps the index (or index partition) metadata and index (or index partition) data.
For non-partitioned indexes, this procedure swaps both the metadata and the index data, and processes the online pending queue.
CTX_DDL.EXCHANGE_SHADOW_INDEX( idx_name IN VARCHAR2 partition_name IN VARCHAR2 default NULL );
Specify the name of the CONTEXT
indextype.
Specify the name of the shadow index partition. May also be NULL.
Example 7-4 Global Index Recreate with Scheduled Swap
This example demonstrates running CTX_DDL.EXCHANGE_SHADOW_INDEX
during non-business hours when query failures and DML blocking can be tolerated.
/* create lexer and original index */ exec ctx_ddl.create_preference('us_lexer','basic_lexer'); create index idx on tbl(text) indextype is ctxsys.context parameters('lexer us_lexer'); /* create a new lexer */ begin ctx_ddl.create_preference('e_lexer','basic_lexer'); ctx_ddl.set_attribute('e_lexer','base_letter','yes'); ctx_ddl.create_preference('m_lexer','multi_lexer'); ctx_ddl.add_sub_lexer('m_lexer','default','us_lexer'); ctx_ddl.add_sub_lexer('m_lexer','e','e_lexer'); end; / /* add new language column to the table for multi-lexer */ alter table tbl add(lang varchar2(10) default 'us'); /* recreate index online with the new multip-lexer */ exec ctx_ddl.create_shadow_index('idx', 'replace lexer m_lexer language column lang'); exec ctx_ddl.exchange_shadow_index('idx');
Using EXCHANGE_SHADOW_INDEX with Non-partitioned Indexes
For non-partitioned indexes, this procedure will swap both metadata and index data, and will process the online pending queue.
Queries will return column not indexed errors when swapping metadata and index data, but queries are processed normally when processing online pending queue. The period of errors being raised should be short.
If you specify POPULATE
when you create the shadow index, and if many DML operations have been issued since the creation of the shadow index, then there could be a large pending queue. However, if you use incremental recreate, that is, specify NOPOPULATE
when you create the shadow index, and you then populate the pending queue and sync, then the online pending queue is always empty no matter how many DML operations have occurred since CREATE_SHADOW_INDEX
was issued.
When this procedure is running, DML will first fail with an error about index being in in-progress status. After that DML could be blocked (hang) if there are rows in online pending queue that need to be reapplied.
Note:
When this procedure is running, DML statements will fail with an error that the index is in "in-progress status." If, when this error occurs, there are rows in the online pending queue that need to be reapplied, then the DML could be blocked and hang.Using EXCHANGE_SHADOW_INDEX with Partitioned Indexes
For partitions that are recreated with NOSWAP
: when the index is partitioned, and if partition_name is a valid index partition, then this procedure will swap the index partition data and the index partition metadata, and will process the online pending queue for this partition.
This procedure swaps only one partition at a time. When you run this procedure on partitions that are recreated with NOSWAP
:
Queries that span multiple partitions will not return consistent results across all partitions.
Queries on the partition that is being swapped will return errors.
Queries on partitions that are already swapped will be based on the new index.
Queries on the partitions that haven't been swapped will be based on the old index.
If the partition_name is NULL, then this procedure will swap the index metadata. Run this procedure as the last step when recreating a local partitioned index online.
See also CTX_DDL.RECREATE_INDEX_ONLINE, CTX_DDL.CREATE_SHADOW_INDEX, and CTX_DDL.DROP_SHADOW_INDEX.
Use this procedure to optimize the index. Optimize your index after you synchronize it. Optimizing an index removes old data and minimizes index fragmentation, which can improve query response time. Querying and DML may proceed while optimization takes place.
You can optimize in fast, full, rebuild, token, or token-type mode.
Fast mode compacts data but does not remove rows.
Full mode compacts data and removes rows.
Optimize in rebuild mode rebuilds the $I
table (the inverted list table) in its entirety. Rebuilding an index is often significantly faster than performing a full optimization, and is more likely to result in smaller indexes, especially if the index is heavily fragmented.
Rebuild optimization creates a more compact copy of the $I
table, and then switches the original $I
table and the copy. The rebuild operation will therefore require enough space to store the copy as well as the original. (If redo logging is enabled, then additional space is required in the redo log as well.) At the end of the rebuild operation, the original $I
table is dropped, and the space can be reused.
Optimize in rebuild mode supports partitioning on the $I
table via the i_table_clause
attribute of the basic_storage
preference with the following limitations:
The i_index_clause
must specify using a local btree index if the $I
table is partitioned.
Partitioning schemes on the token_first
, token_last
, or token_count
columns are not allowed.
In token mode, specify a specific token to be optimized (for example, all rows with documents containing the word elections). Use this mode to optimize index tokens that are frequently searched, without spending time on optimizing tokens that are rarely referenced. An optimized token can improve query response time (but only for queries on that token).
Token-type optimization is similar to token mode, except that the optimization is performed on field sections or MDATA
sections (for example, sections with an <A>
tag). This is useful in keeping critical field or MDATA
sections optimal.
A common strategy for optimizing indexes is to perform regular token optimizations on frequently referenced terms, and to perform rebuild optimizations less frequently. (Use CTX_REPORT.QUERY_LOG_SUMMARY to find out which queries are made most frequently.) You can perform full, fast, or token-type optimizations instead of token optimizations.
Some users choose to perform frequent time-limited full optimizations along with occasional rebuild optimizations.
Note:
Optimizing an index can result in better response time only if you insert, delete, or update documents in the base table after your initial indexing operation.Using this procedure to optimize the index is recommended over using the ALTER
INDEX
statement.
Optimization of a large index may take a long time. To monitor the progress of a lengthy optimization, log the optimization with CTX_OUTPUT.START_LOG and check the resultant logfile from time to time.
Note that, unlike serial optimize full, CTX_DDL.OPTIMIZE_INDEX()
run with optlevel
of FULL
and parallel_degree
> 1 is not resumable. That is, it will not resume from where it left after a time-out or failure.
Note:
There is a very small window of time when a query might fail inCTX_DDL.OPTIMIZE_INDEX
REBUILD
mode when the $I
table is being swapped with the optimized shadow $I
table.CTX_DDL.OPTIMIZE_INDEX(
idx_name IN VARCHAR2, optlevel IN VARCHAR2, maxtime IN NUMBER DEFAULT NULL, token IN VARCHAR2 DEFAULT NULL, part_name IN VARCHAR2 DEFAULT NULL, token_type IN NUMBER DEFAULT NULL, parallel_degree IN NUMBER DEFAULT 1);
);
Specify the name of the index. If you do not specify an index name, then Oracle Text chooses a single index to optimize.
Specify optimization level as a string. You can specify one of the following methods for optimization:
optlevel value | Description |
---|---|
FAST or CTX_DDL.OPTLEVEL_FAST |
This method compacts fragmented rows. However, old data is not removed.
|
FULL or CTX_DDL.OPTLEVEL_FULL |
In this mode you can optimize the entire index or a portion of the index. This method compacts rows and removes old data (deleted rows). Optimizing in full mode runs even when there are no deleted rows.
Full optimization is not supported for |
REBUILD or CTX_DDL.OPTLEVEL_REBUILD |
This optlevel rebuilds the $I table (the inverted list table) to produce more compact token info rows. Like FULL optimize, this mode also deletes information pertaining to deleted rows of the base table.
|
TOKEN or CTX_DDL.OPTLEVEL_TOKEN |
This method lets you specify a specific token to be optimized. Oracle Text does a full optimization on the token you specify with token. If no token type is provided, 0 (zero) will be used as the default.
Use this method to optimize those tokens that are searched frequently. Token optimization is not supported for |
TOKEN_TYPE or CTX_DDL.OPTLEVEL_TOKEN_TYPE |
This optlevel optimizes on demand all tokens in the index matching the input token type.
When Token_type optimization is not supported for |
The behavior of CTX_DDL.OPTIMIZE_INDEX
with respect to the $S index table is as follows:
optlevel value | Will Optimize $S Index Table Yes/No | Notes |
---|---|---|
FAST or CTX_DDL.OPTLEVEL_FAST |
No | |
FULL or CTX_DDL.OPTLEVEL_FULL |
Yes |
|
REBUILD or CTX_DDL.OPTLEVEL_REBUILD |
Yes |
|
TOKEN or CTX_DDL.OPTLEVEL_TOKEN |
No | |
TOKEN_TYPE or CTX_DDL.OPTLEVEL_TOKEN_TYPE |
Yes | You can optimize $S rows for a given SDATA_ID by setting optlevel => TOKEN_TYPE and the TOKEN_TYPE parameter to the target SDATA_ID . |
Specify maximum optimization time, in minutes, for FULL
optimize.
When you specify the symbol CTX_DDL
.MAXTIME_UNLIMITED
(or pass in NULL), the entire index is optimized. This is the default.
Specify the token to be optimized.
If your index is a local index, then you must specify the name of the index partition to synchronize otherwise an error is returned.
If your index is a global, non-partitioned index, then specify NULL, which is the default.
Specify the token_type
to be optimized.
Specify the parallel degree as a number for parallel optimization. The actual parallel degree depends on your resources. Note that when using REBUILD
, setting parallel_degree
to a value greater than 1 still results in serial execution.
Because the following optlevel
values are executed serially, this setting is ignored for them:
TOKEN
or CTX_DDL.OPTLEVEL_TOKEN
FAST
or CTX_DDL.OPTLEVEL_FAST
The following two examples are equivalent ways of optimizing an index using fast optimization:
begin ctx_ddl.optimize_index('myidx','FAST'); end; begin ctx_ddl.optimize_index('myidx',CTX_DDL.OPTLEVEL_FAST); end;
The following example optimizes the index token Oracle:
begin ctx_ddl.optimize_index('myidx','token', TOKEN=>'Oracle'); end;
To optimize all tokens of field section MYSEC
in index MYINDEX
:
begin ctx_ddl.optimize_index('myindex', ctx_ddl.optlevel_token_type, token_type=> ctx_report.token_type('myindex','field mysec text'));end;
You can run CTX_DDL.SYNC_INDEX
and CTX_DDL.OPTIMIZE_INDEX
at the same time. You can also run CTX_DDL.SYNC_INDEX
and CTX_DDL.OPTIMIZE_INDEX
with parallelism at the same time. However, you should not:
Run CTX_DDL.SYNC_INDEX
with parallelism at the same time as CTX_DDL.OPTIMIZE_INDEX
Run CTX_DDL.SYNC_INDEX
with parallelism at the same time as CTX_DDL.OPTIMIZE_INDEX
with parallelism.
If you should run one of these combinations, no error is generated; however, one operation will wait until the other is done.
See also CTX_DDL.SYNC_INDEX and ALTER INDEX.
This procedure populates the pending queue with every rowid in the base table or table partition. This procedure is only supported for CONTEXT
indexes.
This procedure is valuable for large installations that cannot afford to have the indexing process run continuously, and, therefore, need finer control over creating text indexes. The preferred method is to create an empty index, place all the rowids into the pending queue, and build the index through CTX_DDL.SYNC_INDEX.
ctx_ddl.populate_pending( idx_name IN VARCHAR2, part_name IN VARCHAR2 DEFAULT NULL );
Name of the CONTEXT
indextype.
Name of the index partition, if any. Must be provided for local partitioned indexes and must be NULL for global, non-partitioned indexes.
The SYNC_INDEX
is blocked for the duration of the processing. The index unit must be totally empty (idx_docid_count
= 0, idx_nextid
= 1). The rowids of rows waiting to be indexed are inserted into table ctxsys.dr$pending
. You should ensure that there is sufficient space in this table to hold the rowids of the base table.
Recreates the specified index, or recreates the passed-in index partition if the index is local partitioned. For global non-partitioned indexes, this is a one-step procedure. For local partitioned indexes, this procedure must be run separately on every partition after first using CREATE_SHADOW_INDEX to create a shadow policy (or metadata). This procedure is only supported in Enterprise Edition of Oracle Database.
The following changes are not supported:
Transitioning from non-composite domain index to composite, or changing the composite domain index columns.
Rebuilding indexes that have partitioned index tables, for example, $I
, $P
, $K
.
CTX_DDL.RECREATE_INDEX_ONLINE( idx_name IN VARCHAR2, parameter_string IN VARCHAR2 default NULL, parallel_degree IN NUMBER default 1, partition_name IN VARCHAR2 default NULL );
The name of a valid CONTEXT
indextype.
If the index is a global non-partitioned index, specify the same index-level parameter string as in ALTER
INDEX
. Must start with REPLACE
, if it is not NULL
. Optionally specify SWAP
or NOSWAP
. The default is SWAP
.
Reserved for future use. Specify the degree of parallelism. Parallel operation is not supported in the current release.
Specify the name of a valid index partition for a local partitioned index. Otherwise, the default is NULL
. If the index is partitioned, then first pass a partition name, and then specify the partition-level parameter string for ALTER
INDEX
REBUILD
PARTITION
.
Example 7-5 Recreate Simple Global Index
The following example creates an index idx
with a BASIC_LEXER
-based preference us_lexer
. It then recreates the index with a new MULTI_LEXER
based preference m_lexer
in one step. You can use this one step approach when you do not mind that a query might fail for a small window of time at the end of the operation, and DML might get blocked at the beginning for a short time and again at the end.
/* create lexer and original index */ exec ctx_ddl.create_preference('us_lexer','basic_lexer'); create index idx on tbl(text) indextype is ctxsys.context parameters('lexer us_lexer'); /* create a new lexer */ begin ctx_ddl.create_preference('e_lexer','basic_lexer'); ctx_ddl.set_attribute('e_lexer','base_letter','yes'); ctx_ddl.create_preference('m_lexer','multi_lexer'); ctx_ddl.add_sub_lexer('m_lexer','default','us_lexer'); ctx_ddl.add_sub_lexer('m_lexer','e','e_lexer'); end; / /* add new language column to the table for multi-lexer */ alter table tbl add(lang varchar2(10) default 'us'); /* recreate index online with the new multip-lexer */ exec ctx_ddl.recreate_index_online('idx', 'replace lexer m_lexer language column lang');
Example 7-6 Local Index Recreate with All-At-Once Swap
The following example creates a local partitioned index idxp
with a basic lexer us_lexer
. It has two index partitions idx_p1
and idx_p2
. It then recreates a local partitioned index idxp
online with partition idx_p1
, which will have a new storage preference new_store
. The swapping of the partition metadata and index partition data occur at the end. In this example, queries spanning multiple partitions return consistent results across partitions when recreate is in process, except at the end when EXCHANGE_SHADOW_INDEX is running. The extra space required is the combined index size of partition idx_p1
and idx_p2
.
/* create a basic lexer and a local partition index with the lexer*/ exec ctx_ddl.create_preference('us_lexer','basic_lexer'); create index idxp on tblp(text) indextype is ctxsys.context local (partition idx_p1, partition idx_p2) parameters('lexer us_lexer'); /* create new preferences */ begin ctx_ddl.create_preference('my_store','basic_storage'); ctx_ddl.set_attribute('my_store','i_table_clause','tablespace tbs'); end; / begin ctx_ddl.create_preference('e_lexer','basic_lexer'); ctx_ddl.set_attribute('e_lexer','base_letter','yes'); ctx_ddl.create_preference('m_lexer','multi_lexer'); ctx_ddl.add_sub_lexer('m_lexer','default','us_lexer'); ctx_ddl.add_sub_lexer('m_lexer','e','e_lexer'); end; / /* add new language column */ alter table tblp add column (lang varchar2(10) default 'us'); /* create a shadow policy with a new lexer */ exec ctx_ddl.create_shadow_index('idxp', null, 'replace lexer m_lexer language column lang'); /* recreate every index partition online without swapping */ exec ctx_ddl.recreate_index_online('idxp', 'replace storage my_store NOSWAP', 1, 'idx_p1'); exec ctx_ddl.recreate_index_online('idxp','replace NOSWAP',1,'idx_p2'); /* exchange in shadow index partition all at once */ exec ctx_ddl.exchange_shadow_index('idxp', 'idx_p1') /* exchange index partition data*/ exec ctx_ddl.exchange_shadow_index('idxp', 'idx_p2') /* exchange index partition data*/ /* exchange in shadow index metadata */ exec ctx_ddl.exchange_shadow_index('idxp')
Example 7-7 Local Index Recreate with Per-Partition Swap
This example performs the same tasks as Example 7-6, "Local Index Recreate with All-At-Once Swap", except that each index partition is swapped in as it is completed. Queries across all partitions may return inconsistent results in this example.
/* create a basic lexer and a local partition index with the lexer*/ exec ctx_ddl.create_preference('us_lexer','basic_lexer'); create index idxp on tblp(text) indextype is ctxsys.context local (partition idx_p1, partition idx_p2) parameters('lexer us_lexer'); /* create new preferences */ begin ctx_ddl.create_preference('my_store','basic_storage'); ctx_ddl.set_attribute('my_store','i_table_clause','tablespace tbs'); end; / begin ctx_ddl.create_preference('e_lexer','basic_lexer'); ctx_ddl.set_attribute('e_lexer','base_letter','yes'); ctx_ddl.create_preference('m_lexer','multi_lexer'); ctx_ddl.add_sub_lexer('m_lexer','default','us_lexer'); ctx_ddl.add_sub_lexer('m_lexer','e','e_lexer'); end; / /* add new language column */ alter table tblp add column (lang varchar2(10) default 'us'); /* create a shadow policy with a new lexer * exec ctx_ddl.create_shadow_index('idxp', 'replace lexer m_lexer language column lang'); /* recreate every index partition online and swap (default) */ exec ctx_ddl.recreate_index_online('idxp', 'replace storage my_store', 1, 'idx_p1'); exec ctx_ddl.recreate_index_online('idxp', 'replace SWAP', 1, 'idx_p2', /* exchange in shadow index metadata */ exec ctx_ddl.exchange_shadow_index('idxp')
Example 7-8 Scheduled Local Index Recreate with All-At-Once Swap
This example shows the incremental recreation of a local partitioned index, where partitions are all swapped at the end.
/* create a basic lexer and a local partition index with the lexer*/ exec ctx_ddl.create_preference('us_lexer','basic_lexer'); create index idxp on tblp(text) indextype is ctxsys.context local (partition idx_p1, partition idx_p2) parameters('lexer us_lexer'); /* create new preferences */ begin ctx_ddl.create_preference('my_store','basic_storage'); ctx_ddl.set_attribute('my_store','i_table_clause','tablespace tbs'); end; / begin ctx_ddl.create_preference('e_lexer','basic_lexer'); ctx_ddl.set_attribute('e_lexer','base_letter','yes'); ctx_ddl.create_preference('m_lexer','multi_lexer'); ctx_ddl.add_sub_lexer('m_lexer','default','us_lexer'); ctx_ddl.add_sub_lexer('m_lexer','e','e_lexer'); end; / /* add new language column */ alter table tblp add column (lang varchar2(10) default 'us'); /* create a shadow policy with a new lexer * exec ctx_ddl.create_shadow_index('idxp', 'replace lexer m_lexer language column lang'); /* create shadow partition with new storage preference */ exec ctx_ddl.recreate_index_online('idxp', 'replace storage ctxsys.default_storage nopopulate',1,'idx_p1'); exec ctx_ddl.recreate_index_online('idxp', 'replace storage ctxsys.default_storage nopopulate',1,'idx_p2'); declare idxid integer; ixpid integer; begin select idx_id into idxid from ctx_user_indexes where idx_name = 'IDXP'; select ixp_id into ixpid from ctx_user_index_partitions where ixp_index_name = 'IDXP' and ixp_index_partition_name = 'IDX_P1'; /* populate pending */ ctx_ddl.populate_pending('RIO$'||idxid, 'RIO$'||idxid||'#'||ixpid); /* incremental sync ctx_ddl.sync_index('RIO$'||idxid, null, 'RIO$'||idxid||'#'||ixpid, maxtime=>400); /* more incremental sync until no more pending rows */ select ixp_id into ixpid from ctx_user_index_partitions where ixp_index_name = 'IDXP' and ixp_index_partition_name = 'IDX_P2'; /* populate pending */ ctx_ddl.populate_pending('RIO$'||idxid, 'RIO$'||idxid||'#'||ixpid); /* incremental sync ctx_ddl.sync_index('RIO$'||idxid, null, 'RIO$'||idxid||'#'||ixpid, maxtime=>400); /* more incremental sync until no more pending rows */ end; / exec ctx_ddl.exchange_shadow_index('idxp','idx_p1'); exec ctx_ddl.exchange_shadow_index('idxp','idx_p2'); exec ctx_ddl.exchange_shadow_index('idxp');
Example 7-9 Schedule Local Index Recreate with Per-Partition Swap
For incremental recreate where partitions are swapped as they becomes available, follow the steps in example Example 7-8, "Scheduled Local Index Recreate with All-At-Once Swap", except instead of waiting until all syncs are finished before starting exchange shadow index, EXCHANGE_SHADOW_INDEX is done for each partition right after sync is finished.
Using RECREATE_INDEX_ONLINE with Global Non-partitioned Indexes
For global indexes, this procedure provides a one-step process to recreate an index online. It recreates an index, with new preference values, while preserving base table DML and query capability during the recreate process.
Note:
Because the new index is created alongside the existing index, this operation requires additional storage roughly equal to the size of the existing index.Because this procedure is performed online, DML on the base table are permitted during this operation, and are processed as normal. All DML statements that occur during RECREATE_INDEX_ONLINE
are logged into an online pending queue.
Towards the end of the recreate operation, there will be a short duration when DML will fail with an error being raised stating that the index is in an in-progress status. DML may hang again during the process, and the duration will depend on how many DML are logged in the online pending queue since the start of the recreate process.
Note that after the recreate index operation is complete, new information, from all the DML that becomes pending since RECREATE_INDEX_ONLINE
started, may not be immediately reflected. As with creating an index with INDEXTYPE
IS
ctxsys.context
ONLINE
, the index should be synchronized after the recreate index operation is complete, to bring it fully up-to-date.
See Also:
CTX_DDL.CREATE_SHADOW_INDEX and CTX_DDL.EXCHANGE_SHADOW_INDEX for information about how to manually go through each stage of recreation, and to schedule each step to run at a preferred time
The ONLINE
parameter under "Syntax for CONTEXT Index Type"
Syncs issued against the index during the recreate operation are processed against the old, existing data. Syncs are also blocked during the same window when queries return errors. Optimize commands issued against the index during the recreate operation return immediately without error and without processing.
During the recreate operation, the index can be queried normally most of the time. Queries return results based on the existing index and policy (or metadata) until after the final swap.
There is a short interval towards the end of RECREATE_INDEX_ONLINE
when queries will return an error indicating that the column is not indexed. This duration should be short for regular queries. It is mainly the time taken for swapping data segments of the shadow index tables and the index tables, plus the time to delete all the rows in the pending queue. This is the same window of time when DML will fail.
During RECREATE_INDEX_ONLINE
, if you issue DML statements and synchronize them, then you will be able to see the new rows when you query on the existing index. However, after RECREATE_INDEX_ONLINE
finishes (swapping completes and query is on the new index) and before sync is performed, it is possible that you will not be able to query on the new rows, which once could be queried on the old index.
Note:
Transactional queries are not supported.Using RECREATE_INDEX_ONLINE with Local Partitioned Indexes
If the index is local partitioned, you cannot recreate index in one step. You must first create a shadow policy, and then run this procedure for every partition. You can specify SWAP
or NOSWAP
to indicate whether RECREATE_INDEX_ONLINE
partition will swap the index partition data and index partition metadata or not. If the partition was built with NOSWAP
, then another call to EXCHANGE_SHADOW_INDEX
must be invoked later against this partition.
This procedure can also be used to update the metadata (for example, storage preference) of each partition when you specify NOPOPULATE
in the parameter string. This is useful for incremental building of a shadow index through time-limited sync.
If NOPOPULATE
is specified, then NOSWAP
is silently enforced.
During the recreate of the index partition, since no swapping is performed, queries on the partition are processed regularly. Until the swapping stage is reached, queries spanning multiple partitions return consistent results across partitions.
DML and sync are processed normally. Running optimize on partitions that are being recreated, or that have been built (but not swapped), simply returns without doing anything. Running optimize on a partition that has not been rebuilt processes normally.
As with a global index, when all of the partitions use NOSWAP
, the additional storage requirement is roughly equal to the size of the existing index.
Because index partition data and metadata are swapped after index recreate, queries that span multiple partitions will not return consistent results from partition to partition, but will always be correct with respect to each index partition. There is also a short interval towards the end of partition recreate, when the index partition is swapped, during which a query will return a "column not indexed" error.
When partitions are recreated with SWAP
, the additional storage requirement for the operation is equal to the size of the existing index partition.
DML on the partition is blocked. Sync is also blocked during swapping.
See also CREATE_SHADOW_INDEX and DROP_SHADOW_INDEX, and EXCHANGE_SHADOW_INDEX, as well as Oracle Text Application Developer's Guide.
Removes the index with the specified column list from a CTXCAT
index set preference.
Note:
This procedure does not remove aCTXCAT
sub-index from the existing index. To do so, you must drop your index and re-index with the modified index set preference.Use this procedure to remove metadata values, which are associated with an MDATA
section, from a document. Only the owner of the index is allowed to call ADD_MDATA and REMOVE_MDATA
.
CTX_DDL.REMOVE_MDATA( idx_name IN VARCHAR2, section_name IN VARCHAR2, values SYS.ODCIVARCHAR2LIST, rowids SYS.ODCIRIDLIST, [part_name] IN VARCHAR2] );
Name of the text index that contains the named rowids.
Name of the MDATA
section.
List of metadata values. If a metadata value contains a comma, the comma must be escaped with a backslash.
Rowids
from which to remove the metadata values.
Name of the index partition, if any. Must be provided for local partitioned indexes and must be NULL for global, non-partitioned indexes.
This example removes the MDATA
value blue from the MDATA
section BGCOLOR
.
ctx_ddl.remove_mdata('idx_docs', 'bgcolor', 'blue', 'rows');
See also "ADD_MDATA"; "ADD_MDATA_SECTION"; "MDATA"; as well as the Section Searching chapter of Oracle Text Application Developer's Guide.
The REMOVE_SECTION
procedure removes the specified section from the specified section group. You can specify the section by name or ID. View section ID with the CTX_USER_SECTIONS
view.
Use the following syntax to remove a section by section name:
CTX_DDL.REMOVE_SECTION( group_name in varchar2, section_name in varchar2 );
Specify the name of the section group from which to delete section_name
.
Specify the name of the section to delete from group_name
.
Use the following syntax to remove a section by section ID:
CTX_DDL.REMOVE_SECTION( group_name in varchar2, section_id in number );
Specify the name of the section group from which to delete section_id
.
Specify the section ID of the section to delete from group_name
.
The following example drops a section called Title
from the htmgroup
:
begin ctx_ddl.remove_section('htmgroup', 'Title'); end;
Removes a stopclass from a stoplist.
CTX_DDL.REMOVE_STOPCLASS( stoplist_name in varchar2, stopclass in varchar2 );
Specify the name of the stoplist.
Specify the name of the stopclass to be removed.
The following example removes the stopclass NUMBERS
from the stoplist mystop
.
begin ctx_ddl.remove_stopclass('mystop', 'NUMBERS'); end;
Removes a stoptheme from a stoplist.
CTX_DDL.REMOVE_STOPTHEME( stoplist_name in varchar2, stoptheme in varchar2 );
Specify the name of the stoplist.
Specify the stoptheme to be removed from stoplist_name
.
The following example removes the stoptheme banking from the stoplist mystop
:
begin ctx_ddl.remove_stoptheme('mystop', 'banking'); end;
Removes a stopword from a stoplist. To have the removal of a stopword be reflected in the index, you must rebuild your index.
CTX_DDL.REMOVE_STOPWORD(
stoplist_name in varchar2, stopword in varchar2, language in varchar2 default NULL
);
Specify the name of the stoplist.
Specify the stopword to be removed from stoplist_name
.
Specify the language of stopword
to remove when the stoplist you specify with stoplist_name
is of type MULTI_STOPLIST
. You must specify the globalization support name or abbreviation of an Oracle Text-supported language. You can also remove ALL
stopwords.
The following example removes a stopword because from the stoplist mystop
:
begin
ctx_ddl.remove_stopword('mystop','because');
end;
Removes a sub-lexer from a multi-lexer preference. You cannot remove the lexer for DEFAULT
.
CTX_DDL.REMOVE_SUB_LEXER(
lexer_name in varchar2, language in varchar2 default NULL
);
Specify the name of the multi-lexer preference.
Specify the language of the sub-lexer to remove. You must specify the globalization support name or abbreviation of an Oracle Text-supported language.
The following example removes a sub-lexer german_lexer of language german
:
begin
ctx_ddl.remove_sub_lexer('german_lexer','german');
end;
Use this procedure to replace metadata in local domain indexes at the global (index) level.
Note:
TheALTER INDEX PARAMETERS
command performs the same function as this procedure and can replace more than just metadata. For that reason, using ALTER INDEX PARAMETERS
is the preferred method of replacing metadata at the global (index) level and should be used in place of this procedure when possible. For more information, see "ALTER INDEX PARAMETERS Syntax".
CTX_REPLACE_INDEX_METADATA
may be deprecated in a future release of Oracle Text.
CTX_DDL.REPLACE_INDEX_METADATA(idx_name IN VARCHAR2, parameter_string IN VARCHAR2);
Specify the name of the index whose metadata you want to replace.
Specify the parameter string to be passed to ALTER INDEX
. This must begin with 'REPLACE METADATA
'.
ALTER INDEX REBUILD PARAMETERS ('REPLACE METADATA')
does not work for a local partitioned index at the index (global) level; you cannot, for example, use that ALTER INDEX
syntax to change a global preference, such as filter or lexer type, without rebuilding the index. Therefore, CTX_DDL.REPLACE_INDEX_METADATA
is provided as a method of overcoming this limitation of ALTER INDEX
.
Though it is meant as a way to replace metadata for a local partitioned index, CTX_DDL.REPLACE_INDEX_METADATA
can be used on a global, non-partitioned index, as well.
REPLACE_INDEX_METADATA
cannot be used to change the sync type at the partition level; that is, parameter_string cannot be 'REPLACE METADATA SYNC
'. For that purpose, use ALTER INDEX REBUILD PARTITION
to change the sync type at the partition level.
See also "ALTER INDEX PARAMETERS Syntax" and "ALTER INDEX REBUILD Syntax".
Sets a preference attribute. Use this procedure after you have created a preference with CTX_DDL.CREATE_PREFERENCE.
CTX_DDL.SET_ATTRIBUTE(preference_name IN VARCHAR2, attribute_name IN VARCHAR2, attribute_value IN VARCHAR2);
Specify the name of the preference.
Specify the name of the attribute.
Specify the attribute value. Specify boolean values as TRUE
or FALSE
, T
or F
, YES
or NO
, Y
or N
, ON
or OFF
, or 1
or 0
.
The following example creates a data storage preference called filepref
that tells the system that the files to be indexed are stored in the operating system. The example then uses CTX_DDL.SET_ATTRIBUTE to set the PATH
attribute to the directory /docs
.
begin ctx_ddl.create_preference('filepref', 'FILE_DATASTORE'); ctx_ddl.set_attribute('filepref', 'PATH', '/docs'); end;
See Also:
For more information about data storage, see "Datastore Types"For more examples of using SET_ATTRIBUTE
, see "CREATE_PREFERENCE"
Synchronizes the index to process inserts, updates, and deletes to the base table.
Note:
BecauseCTX_DDL.SYNC_INDEX
issues implicit commits, calling CTX_DDL.SYNC_INDEX
in a trigger is strongly discouraged. Doing so can result in errors being raised, as both SYNC_INDEX
and post-commit $R
LOB
maintenance try to update the same $R
LOB
.CTX_DDL.SYNC_INDEX(
idx_name IN VARCHAR2 DEFAULT NULL memory IN VARCHAR2 DEFAULT NULL, part_name IN VARCHAR2 DEFAULT NULL, parallel_degree IN NUMBER DEFAULT 1 maxtime IN NUMBER DEFAULT NULL, locking IN NUMBER DEFAULT LOCK_WAIT );
Specify the name of the index to synchronize.
Note:
Whenidx_name
is null, all CONTEXT
, CTXRULE
, and CTXXPATH
indexes that have pending changes are synchronized. You must be connected as ctxsys
to perform this operation. Each index or index partition is synchronized in sequence, one after the other. Because of this, the individual syncs are performed with locking set to NOWAIT
and maxtime set to 0
. Any values that you specify for locking or maxtime on the SYNC_INDEX
call are ignored. However, the memory
and parallel_degree
parameters are passed on to the individual synchronizations.Specify the runtime memory to use for synchronization. This value overrides the DEFAULT_INDEX_MEMORY
system parameter.
The memory parameter specifies the amount of memory Oracle Text uses for the synchronization operation before flushing the index to disk. Specifying a large amount of memory:
Improves indexing performance because there is less I/O
Improves query performance and maintenance because there is less fragmentation
The indexing memory size specified in the second argument applies to each parallel slave. For exmaple, if the memory
argument is set to 500M and parallel_degree
is set to 2, then ensure that there is at least 1GB of memory available on the system used for the parallel SYNC_INDEX
.
Specifying smaller amounts of memory increases disk I/O and index fragmentation, but might be useful when runtime memory is scarce.
If your index is a local index, then you must specify the name of the index partition to synchronize otherwise an error is returned.
If your index is a global, non-partitioned index, then specify NULL, which is the default.
Specify the degree to run parallel synchronize. A number greater than 1 turns on parallel synchronize. The actual degree of parallelism might be smaller depending on your resources.
Indicate a suggested time limit on the operation, in minutes. SYNC_INDEX
will process as many documents in the queue as possible within the time limit. The maxtime
value of NULL is equivalent to CTX_DDL.MAXTIME_UNLIMITED
. This parameter is ignored when SYNC_INDEX
is invoked without an index name, in which case maxtime
value of 0 is used instead. The locking
parameter is ignored for automatic syncs (that is, SYNC
ON
COMMIT
or SYNC
EVERY
).
The time limit specified is treated as approximate. The actual time taken may be somewhat less than or greater than what you specify. The "time clock" for maxtime
does not start until the SYNC lock is acquired.
Configure how SYNC_INDEX
deals with the situation where another sync is already running on the same index or index partition. When locking is ignored because SYNC_INDEX
is invoked without an index name, then locking value of LOCK_NOWAIT
is used instead. The locking
parameter is ignored for automatic syncs (that is, SYNC
ON
COMMIT
or SYNC
EVERY
).
The options for locking
are:
CTX_DDL.LOCK_WAIT |
If another sync is running, wait until the running sync is complete, then begin sync. (In the event of not being able to get a lock, it will wait forever and ignore the maxtime setting.) |
CTX_DDL.LOCK_NOWAIT |
If another sync is running, immediately returns without error. |
CTX_DDL.LOCK_NOWAIT_ERROR |
If another sync is running, error "DRG-51313: timeout while waiting for DML or optimize lock" is raised. |
The following example synchronizes the index myindex
with 2 megabytes of memory:
begin
ctx_ddl.sync_index('myindex', '2M');
end;
The following example synchronizes the part1
index partition with 2 megabytes of memory:
begin
ctx_ddl.sync_index('myindex', '2M', 'part1');
end;
You can run CTX_DDL.SYNC_INDEX
and CTX_DDL.OPTIMIZE_INDEX
at the same time. You can also run CTX_DDL.SYNC_INDEX
and CTX_DDL.OPTIMIZE_INDEX
with parallelism at the same time. However, you should not run CTX_DDL.SYNC_INDEX
with parallelism at the same time as CTX_DDL.OPTIMIZE_INDEX
, nor CTX_DDL.SYNC_INDEX
with parallelism at the same time as CTX_DDL.OPTIMIZE_INDEX
with parallelism. If you should run one of these combinations, no error is generated; however, one operation will wait until the other is done.
Removes a set attribute from a preference.
CTX_DDL.UNSET_ATTRIBUTE(preference_name varchar2, attribute_name varchar2);
Specify the name of the preference.
Specify the name of the attribute.
Enabling/Disabling Alternate Spelling
The following example shows how you can enable alternate spelling for German and disable alternate spelling with CTX_DDL.UNSET_ATTRIBUTE
:
begin ctx_ddl.create_preference('GERMAN_LEX', 'BASIC_LEXER'); ctx_ddl.set_attribute('GERMAN_LEX', 'ALTERNATE_SPELLING', 'GERMAN'); end;
To disable alternate spelling, use the CTX_DDL.UNSET_ATTRIBUTE
procedure as follows:
begin ctx_ddl.unset_attribute('GERMAN_LEX', 'ALTERNATE_SPELLING'); end;
Updates a policy created with CREATE_POLICY
. Replaces the preferences of the policy. Null arguments are not replaced.
CTX_DDL.UPDATE_POLICY( policy_name IN VARCHAR2, filter IN VARCHAR2 DEFAULT NULL, section_group IN VARCHAR2 DEFAULT NULL, lexer IN VARCHAR2 DEFAULT NULL, stoplist IN VARCHAR2 DEFAULT NULL, wordlist IN VARCHAR2 DEFAULT NULL);
Specify the name of the policy to update.
Specify the filter preference to use.
Specify the section group to use.
Specify the lexer preference to use.
Specify the stoplist to use.
Specify the wordlist to use.