štvrtok 13. septembra 2012

How to create and enable fulltext for documents on MS SQL Server 2008

This is real working example:
database name = sps
database owner name = sps
table name = DR_BLOBSTORAGE
column name with content = CONTENT
PK = SID
PK index name = DBL_PK

You need to have a table with this three types of columns
CREATE TABLE [dbo].[DR_BLOBSTORAGE](
    [SID] [dbo].[SID] NOT NULL,
    [CONTENT] [image] NULL,
    [DOC_TYPE] [varchar](10) NULL,
 CONSTRAINT [DBL_PK] PRIMARY KEY CLUSTERED
(
    [SID] ASC
)WITH (PAD_INDEX  = OFF, STATISTICS_NORECOMPUTE  = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS  = ON, ALLOW_PAGE_LOCKS  = ON) ON [PRIMARY]
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]




1. Check if fulltext is enabled on the database and enable it.
USE sps
if (select DATABASEPROPERTY(DB_NAME(), N'IsFullTextEnabled')) <> 1
exec sp_fulltext_database N'enable'


2.  Create fulltext catalog with name spsdr_catalog, case insensitive.
CREATE FULLTEXT CATALOG [spsdr_catalog] WITH ACCENT_SENSITIVITY = OFF
AUTHORIZATION [sps]
.

Later, you can manage it here in MS SQL Management Studio


3. Get all languages possible to index.
SELECT * FROM sys.fulltext_languages
 
 3. Create fulltext index
CREATE FULLTEXT INDEX ON [dbo].[DR_BLOBSTORAGE]
(
        CONTENT                         --Full-text index column name
        TYPE COLUMN DOC_TYPE    --Name of column that contains file type information
        Language 1051                 --1051 is LCID for the Slovak language
)
    KEY INDEX DBL_PK
    ON spsdr_catalog
    WITH CHANGE_TRACKING OFF, NO POPULATION;



4. Start population (indexing)
ALTER FULLTEXT INDEX ON [dbo].[DR_BLOBSTORAGE]
   START FULL POPULATION;


5. Check population status:
select objectproperty(object_id('[dbo].[DR_BLOBSTORAGE]'), 'tablefulltextpopulatestatus') as TableFullTextPopulateStatus

0 = Idle.
1 = Full population is in progress.
2 = Incremental population is in progress.
3 = Propagation of tracked changes is in progress.
4 = Background update index is in progress, such as automatic change tracking.
5 = Full-text indexing is throttled or paused. 


Starting status will be 1, but after a while  (depending of  the count of  documents already in database) it will change to 0.

6. Test fulltext search
select * from dr_blobstorage  where  contains(CONTENT,'Test')  

enjoy

MichalC

Žiadne komentáre:

Zverejnenie komentára