CONTAINS

You can use the CONTAINS function to search a text search index using criteria you specify in a search argument. The function returns a result indicating whether a match was found.

Read syntax diagramSkip visual syntax diagramCONTAINS( column-name,search-argument, string-constant)1
Notes:
  • 1 string-constant must conform to the rules for the search-argument options.
search-argument-options
Read syntax diagramSkip visual syntax diagramQUERYLANGUAGE=valueRESULTLIMIT=valueSYNONYM=OFFON
Read syntax diagramSkip visual syntax diagram1
Notes:
  • 1 The same clause must not be specified more than once.

The schema is QSYS2.

column-name
Specifies a qualified or unqualified name of a column that has a text search index that is to be searched. The column must exist in the table or view that is identified in the FROM clause of the statement. The column of the table, or the column of the underlying base table of the view, must have an associated text search index (SQLSTATE 38H12). The underlying expression of the column of a view must be a simple column reference to the column of an underlying table, directly or through another nested view.
search-argument
Specifies an expression that returns a string value containing the terms used in the search. The expression must not be all blanks or the empty string (SQLSTATE 38H14). The actual length of the string must not exceed 32704 bytes. This length might be further limited by what is supported by the text search server (SQLSTATE 38H10). The value is converted to Unicode before it is used to search the text search index.
string-constant
Identifies a string constant that specifies the search argument options that are in effect for the function.

The options that can be specified as part of the search-argument-options are as follows:

QUERYLANGUAGE = value
Specifies the query language. The value can be any of the supported language codes. If the QUERYLANGUAGE option is not specified, the default is the language value of the text search index that is used when this function is invoked. If the language value of the text search index is AUTO, the default value for QUERYLANGUAGE is en_US.
RESULTLIMIT = value
Specifies the maximum number of results to be returned from the underlying search engine. The value can be an integer value 1 - 2 147 483 647. If the RESULTLIMIT option is not specified, no result limit is in effect for the query.

This scalar function might not be called for each row of the result table, depending on the plan that the optimizer chooses. This function can be called once for the entire query to the underlying search engine. A result set of all the primary keys that match are returned. This result set is then joined to the table containing the column to identify the result rows. In this case, the RESULTLIMIT value acts like FETCH FIRST ?? ROWS from the underlying text search engine, and can be used as an optimization. If the search engine is called for each row of the result because that is the best plan, then the RESULTLIMIT option is ignored.

SYNONYM = OFF or SYNONYM = ON
Specifies whether to use a synonym dictionary that is associated with the text search index. You can add a synonym dictionary to a collection by using the synonym tool.
OFF
OFF is the default value.
ON
Use the synonym dictionary that is associated with the text search index.

The result of the function is a large integer. If the second argument can be null, the result can be null. If the second argument is null, the result is the null value.

The result is 1 if the document contains a match for the search criteria that are specified in the search argument. Otherwise, the result is 0. The result is also 0 if the column is null. If the search argument is Null, then the result is the null value.

CONTAINS is a nondeterministic function.

Example 1

The following statement finds all the employees who have ″COBOL″ in their resume.
SELECT EMPNO
FROM EMP_RESUME
WHERE RESUME_FORMAT = 'ascii'
AND CONTAINS(RESUME, 'COBOL') = 1

Example 2

The search argument does not need to be a string constant. The search argument can be any SQL string expression, including a string contained in a host variable. The following statement searches for the exact term "ate" in the COMMENT column.
Note: The term "ate" must be delimited in double quotes so that only the exact term is searched for and linguistic variations are not considered.
char search_arg[100]; /* input host variable */  
...  
EXEC SQL DECLARE C3 CURSOR FOR
SELECT CUSTKEY
FROM K55ADMIN.CUSTOMERS
WHERE CONTAINS(COMMENT, :search_arg)= 1
ORDER BY CUSTKEY;
strcpy(search_arg, "\"ate\""');
EXEC SQL OPEN C3; 
...  

Example 3

The following statement finds 10 students at random who wrote online essays that contain the phrase "fossil fuel" in Spanish, which is "combustible fósil." These students are for a radio interview. Use the synonym dictionary that was created for the associated text search index. Because only 10 students are needed, optimize the query by using the RESULTLIMIT option to limit the number of results from the underlying text search server.

SELECT FIRSTNME, LASTNAME 
   FROM STUDENT_ESSAYS 
   WHERE CONTAINS(TERM_PAPER, 'combustible fósil', 
      'QUERYLANGUAGE= es_ES RESULTLIMIT  = 10 SYNONYM=ON') = 1