Udostępnij za pośrednictwem


CREATE FULLTEXT INDEX (Transact-SQL)

Creates a full-text index on one or more columns of a table or indexed view in a database. Only one full-text index is allowed per table or indexed view. By default, a database is enabled for full-text search when the database is created.

Topic link iconTransact-SQL Syntax Conventions

Syntax

CREATE FULLTEXT INDEX ON table_name
     [(column_name [TYPE COLUMN type_column_name] 
          [LANGUAGE language_term] [,...n])]
     KEY INDEX index_name
          [ON fulltext_catalog_name]
     [WITH 
          {CHANGE_TRACKING {MANUAL | AUTO | OFF [, NO POPULATION]}}
     ]

Arguments

  • table_name
    Is the name of the table or indexed view that contains the column or columns included in the full-text index.
  • column_name
    Is the name of the column or columns included in the full-text index. Only columns of type char, varchar, nchar, nvarchar, text, ntext, image, xml, and varbinary can be indexed for full-text search.
  • TYPE COLUMN type_column_name
    Is the name of the column in table_name that holds the document type of column_name.

    type_column_name must be of type char, nchar, varchar, or nvarchar. Specify type_column_name only if the column or columns in column_name are of type varbinary(max) or image; otherwise, SQL Server returns an error.

    For more information, see Full-Text Search Filters.

  • LANGUAGE language_term
    Is the language of the data stored in column_name.

    language_term is optional and can be specified as a string, integer, or hexadecimal value corresponding to the locale identifier (LCID) of a language. If language_term is specified, the language it represents will be used to index data stored in char, nchar, varchar, nvarchar, text, and ntext columns. This language is the default language used at query time if language_term is not specified as part of a full-text predicate against the column. If no value is specified, the default language of the SQL Server instance is used.

    If the language is unknown, or there are multiple languages that are to be stored in column_name (and the column is not of BLOB or XML data type), use the neutral (0x0) language. For more information, see International Considerations for Full-Text Search.

    Use the sp_configure stored procedure to access information about the default full-text language of the Microsoft SQL Server instance. For more information, see sp_configure (Transact-SQL) and default full-text language Option.

    When specified as a string, language_term corresponds to the alias column value in the syslanguages system table. The string must be enclosed in single quotation marks, as in 'language_term'. When specified as an integer, language_term is the actual LCID that identifies the language. When specified as a hexadecimal value, language_term is 0x followed by the hex value of the LCID. The hex value must not exceed eight digits, including leading zeros.

    If the value is in double-byte character set (DBCS) format, SQL Server will convert it to Unicode.

    Resources, such as word breakers and stemmers, must be enabled for the language specified as language_term. If such resources do not support the specified language, SQL Server returns an error.

    For non-BLOB and non-XML columns containing text data in multiple languages, or for cases when the language of the text stored in the column is unknown, use the neutral (0x0) language resource. For documents stored in XML- or BLOB-type columns, the language encoding within the document will be used at indexing time. For example, in XML columns, the xml:lang attribute in XML documents will identify the language. At query time, the value previously specified in language_term becomes the default language used for full-text queries unless language_term is specified as part of a full-text query.

  • ,... n
    Indicates that multiple columns can be specified to be full-text indexed. When multiple columns are specified, separate each column with a comma.
  • KEY INDEX index_name
    Is the name of the unique key index on table_name. The KEY INDEX must be a unique, single-key, non-nullable column. Select the smallest unique key index for the full-text unique key. For best performance, a CLUSTERED index is recommended.
  • ON fulltext_catalog_name
    Is the full-text catalog used for the full-text index. The catalog must already exist in the database. This clause is optional. If it is not specified, a default catalog is used. If no default catalog exists, SQL Server returns an error.

    The filegroup of fulltext_catalog_name or, if no catalog is specified, the default full-text catalog must not be READONLY or OFFLINE. Otherwise, SQL Server returns an error.

  • WITH CHANGE_TRACKING {MANUAL | AUTO | OFF [ , NO POPULATION]}
    Specifies whether or not SQL Server maintains a list of all changes to the indexed data. Data changes through WRITETEXT and UPDATETEXT are not picked up with change tracking.

    • MANUAL
      Specifies that the change-tracking log will be propagated either on a schedule using SQL Server Agent, or manually by the user.
    • AUTO
      Specifies that SQL Server automatically updates the full-text index as the data is modified in the associated tables. AUTO is the default.

      Note   Although changes can be propagated automatically, these changes may not be reflected immediately in the full-text index. For more information about properties used for monitoring the full-text indexing process and for diagnosing any problems with full-text indexing, see Obtaining Full-Text Property Values Using Transact-SQL Functions.

    • OFF [ , NO POPULATION]
      Specifies that SQL Server does not keep a list of changes to the indexed data.

      The NO POPULATION option can be used only when CHANGE_TRACKING is OFF. When NO POPULATION is specified, SQL Server does not populate an index after it is created. The index is only populated after the user executes the ALTER FULLTEXT INDEX command with the START FULL, or INCREMENTAL POPULATION clause. When NO POPULATION is not specified, SQL Server populates the index fully after it is created.

Permissions

User must have REFERENCES permission on the full-text catalog and have ALTER permission on the table of view, or be a member of the sysadmin fixed server role, or db_owner, or db_ddladmin fixed database roles.

Examples

The following example creates a full-text index on the HumanResources.JobCandidate table.

USE AdventureWorks;
GO
CREATE UNIQUE INDEX ui_ukJobCand ON HumanResources.JobCandidate(JobCandidateID);
CREATE FULLTEXT CATALOG ft AS DEFAULT;
CREATE FULLTEXT INDEX ON HumanResources.JobCandidate(Resume) KEY INDEX ui_ukJobCand;
GO

See Also

Reference

ALTER FULLTEXT INDEX (Transact-SQL)
DROP FULLTEXT INDEX (Transact-SQL)
GRANT (Transact-SQL)

Other Resources

Full-Text Search

Help and Information

Getting SQL Server 2005 Assistance

Change History

Release History

12 December 2006

New content:
  • Clarified that full-text indexes can also be applied on indexed views.
  • Added a link to the Filters topic to clarify the TYPE COLUMN clause.