full text index 探秘(1)

[oracle@roger ~]$ sqlplus "/as sysdba"

SQL*Plus: Release 10.2.0.4.0 - Production on Sun Aug 28 17:17:45 2011
Copyright (c) 1982, 2007, Oracle.  All Rights Reserved.
Connected to an idle instance.
SQL> startup

ORACLE instance started.
Total System Global Area  167772160 bytes
Fixed Size                  1266392 bytes
Variable Size              71306536 bytes
Database Buffers           92274688 bytes
Redo Buffers                2924544 bytes
Database mounted.
Database opened.

SQL> create user text_idx identified by text_idx;
User created.

SQL> grant resource ,connect,ctxapp to text_idx;
Grant succeeded.

SQL> GRANT EXECUTE ON CTXSYS.CTX_CLS TO text_idx;
Grant succeeded.

SQL> GRANT EXECUTE ON CTXSYS.CTX_DDL TO text_idx;
Grant succeeded.

SQL> GRANT EXECUTE ON CTXSYS.CTX_DOC TO text_idx;
Grant succeeded.

SQL> GRANT EXECUTE ON CTXSYS.CTX_OUTPUT TO text_idx;
Grant succeeded.

SQL> GRANT EXECUTE ON CTXSYS.CTX_QUERY TO text_idx;
Grant succeeded.

SQL> GRANT EXECUTE ON CTXSYS.CTX_REPORT TO text_idx;
Grant succeeded.

SQL> GRANT EXECUTE ON CTXSYS.CTX_THES TO text_idx;
Grant succeeded.

SQL> GRANT EXECUTE ON CTXSYS.CTX_ULEXER TO text_idx;
Grant succeeded.

SQL> conn text_idx/text_idx
Connected.

SQL> CREATE TABLE docs (id NUMBER PRIMARY KEY, text VARCHAR2(500));
Table created.

SQL> INSERT INTO docs VALUES(1, 'http://www.itpub.net/thread-1475450-1-1.html');
1 row created.

SQL> INSERT INTO docs VALUES(2, 'http://www.yesky.com/285/1942785_1.shtml');
1 row created.

SQL> INSERT INTO docs VALUES(3, 'http://www.baidu.com/s?tn=chenly082=4391');
1 row created.

SQL> INSERT INTO docs VALUES(4, 'file:///D:/oracle---官方文档/B19306_01/B19306_01/text.102/b14217/quicktour.htmi1008362');
1 row created.

SQL> INSERT INTO docs VALUES(5, 'file:///D:/oracle---官方文档/B19306_01/B19306_01/text.102/b14217/acase.htm#g637598');
1 row created.

SQL> INSERT INTO docs VALUES(6, 'http://database.51cto.com/art/201104/252898.htm');
1 row created.

SQL> commit;
Commit complete.

SQL> select count(*) from docs;

  COUNT(*)
----------
         6

SQL> col text for a50
SQL> set lines 120
SQL> SELECT  id, text FROM docs WHERE CONTAINS(text, 'baidu', 1) > 0;

        ID TEXT
---------- --------------------------------------------------
         3 http://www.baidu.com/s?tn=chenly082=4391

SQL> set autot traceonly
SQL> SELECT  id, text FROM docs WHERE CONTAINS(text, 'baidu', 1) > 0;

Execution Plan
----------------------------------------------------------
Plan hash value: 3588628665

----------------------------------------------------------------------------------------
| Id  | Operation                   | Name     | Rows  | Bytes | Cost (%CPU)| Time     |
----------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |          |     1 |   277 |     4   (0)| 00:00:01 |
|   1 |  TABLE ACCESS BY INDEX ROWID| DOCS     |     1 |   277 |     4   (0)| 00:00:01 |
|*  2 |   DOMAIN INDEX              | IDX_DOCS |       |       |     4   (0)| 00:00:01 |
----------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access("CTXSYS"."CONTAINS"("TEXT",'baidu',1)>0)

Note
-----
   - dynamic sampling used for this statement

Statistics
----------------------------------------------------------
         11  recursive calls
          0  db block gets
         18  consistent gets
          0  physical reads
          0  redo size
        500  bytes sent via SQL*Net to client
        400  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          1  rows processed

SQL>  create sequence seq_docs
  2   minvalue 1
  3   nomaxvalue
  4   start with 7
  5   increment by 1
  6   nocycle
  7   cache 10;

Sequence created.

SQL> begin
  2  for i in 1..100 loop
  3  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/');
  4  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=210');
  5  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=216');
  6  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=201');
  7  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=196');
  8  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=219');
  9  commit;
 10  end loop;
 11  end;
 12  /

PL/SQL procedure successfully completed.

SQL> select count(*) from docs;

  COUNT(*)
----------
       606

SQL> begin
  2  for i in 1..1000 loop
  3  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/');
  4  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=210');
  5  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=216');
  6  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=201');
  7  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=196');
  8  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=219');
  9  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=205');
 10  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=206');
 11  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=207');
 12  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=199');
 13  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=208');
 14  commit;
 15  end loop;
 16  end;
 17  /

PL/SQL procedure successfully completed.

SQL> select count(*) from docs;

  COUNT(*)
----------
     11606

SQL> set timing on
SQL> begin
  2  for i in 1..10000 loop
  3  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/');
  4  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=210');
  5  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=216');
  6  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=201');
  7  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=196');
  8  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=219');
  9  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=205');
 10  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=206');
 11  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=207');
 12  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=199');
 13  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=208');
 14  commit;
 15  end loop;
 16  end;
 17  /

PL/SQL procedure successfully completed.

Elapsed: 00:03:43.23

SQL> select count(*) from docs;

  COUNT(*)
----------
    121606

Elapsed: 00:00:00.05

SQL> select count(*) from docs where CONTAINS(text,'p=210') > 0;

  COUNT(*)
----------
         0

SQL> select count(*) from docs where CONTAINS(text,'killdb') >0;

  COUNT(*)
----------
         0

SQL> EXEC CTX_DDL.SYNC_INDEX('idx_docs', '5m');

PL/SQL procedure successfully completed.

SQL> select count(*) from docs where CONTAINS(text,'p=210') > 0;

  COUNT(*)
----------
    110500


SQL> SELECT  count(*) FROM docs WHERE CONTAINS(text,'killdb') > 0;

  COUNT(*)
----------
    121600

从这里看出 同步index的重要性了,下面来创建job 来进行定期的同步index以及优化。

SQL> create or replace procedure sync_idx_docs as
  2   begin
  3      ctx_ddl.sync_index('idx_docs');
  4   end;
  5   /

Procedure created.

SQL> VARIABLE job_no number;
SQL>  BEGIN
  2      DBMS_JOB.SUBMIT(:job_no,'sync_idx_docs();',
  3      SYSDATE, 'SYSDATE + 1');
  4      commit;
  5   END;
  6   /

PL/SQL procedure successfully completed.

SQL> create or replace procedure optimize_idx_docs as
  2      begin
  3      ctx_ddl.optimize_index('idx_docs','FULL');
  4  end;
  5  /

Procedure created.

SQL> VARIABLE job_no number;
SQL> BEGIN
  2      DBMS_JOB.SUBMIT(:job_no,'optimize_idx_docs();',
  3      SYSDATE, 'SYSDATE + 1');
  4      commit;
  5  END;
  6  /

PL/SQL procedure successfully completed.


SQL> col INTERVAL for a25
SQL> select JOB,LOG_USER,SCHEMA_USER,INTERVAL,LAST_DATE from user_jobs;

       JOB LOG_USER      SCHEMA_USER     INTERVAL         LAST_DATE
---------- ------------- --------------- ---------------- ---------
        21 TEXT_IDX      TEXT_IDX        SYSDATE + 1      28-AUG-11
        22 TEXT_IDX      TEXT_IDX        SYSDATE + 1      28-AUG-11

---启动如上2个job任务

SQL> execute dbms_job.run(21);
PL/SQL procedure successfully completed.

SQL> execute  dbms_job.run(22);
PL/SQL procedure successfully completed.

SQL> alter table docs add owner varchar2(10);
Table altered.

SQL> update docs set owner='Roger';

121606 rows updated.

SQL> commit;

Commit complete.

下面来测试,如果表docs dml操作比较频繁,那么对于select语句来说,是否有较大的影响?

SQL> select /*+ no_index(docs SYS_C005195)*/
2   count(*)
3    from docs
4   where contains(text, 'p=199') > 0
5     and id > 10500
6     and id < 10800;
Elapsed: 00:00:00.09
Execution Plan
----------------------------------------------------------
Plan hash value: 1092983528
-----------------------------------------------------------------------------------------
| Id  | Operation                    | Name     | Rows  | Bytes | Cost (%CPU)| Time     |
-----------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |          |     1 |   277 |     4   (0)| 00:00:01 |
|   1 |  SORT AGGREGATE              |          |     1 |   277 |            |          |
|*  2 |   TABLE ACCESS BY INDEX ROWID| DOCS     |     1 |   277 |     4   (0)| 00:00:01 |
|*  3 |    DOMAIN INDEX              | IDX_DOCS |       |       |     4   (0)| 00:00:01 |
-----------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter("ID">10500 AND "ID"<10800)
3 - access("CTXSYS"."CONTAINS"("TEXT",'p=199')>0)
Note
-----
- dynamic sampling used for this statement
---session 1
SQL> show user
USER is "TEXT_IDX"
SQL> begin
2    for i in 1 .. 15000 loop
3      if mod(i, 2) = 0 then
4        update docs
5           set owner = 'killdb'
6         where id = i
7           and id > 10000
8           and id < 15000;
9        commit;
10      end if;
11    end loop;
12    commit;
13  end;
14  /
PL/SQL procedure successfully completed.
---session 2
SQL> select /*+ no_index(docs SYS_C005195)*/
2   id,owner,text
3    from docs
4   where contains(text, 'p=199') > 0
5     and id > 10700
6     and id < 10800;
90 rows selected.
Elapsed: 00:00:00.19
Statistics
----------------------------------------------------------
13  recursive calls
0  db block gets
17447  consistent gets
0  physical reads
1024  redo size
4691  bytes sent via SQL*Net to client
455  bytes received via SQL*Net from client
7  SQL*Net roundtrips to/from client
0  sorts (memory)
0  sorts (disk)
90  rows processed
SQL> /
90 rows selected.
Elapsed: 00:00:00.35
Statistics
----------------------------------------------------------
13  recursive calls
0  db block gets
21322  consistent gets
0  physical reads
0  redo size
4689  bytes sent via SQL*Net to client
455  bytes received via SQL*Net from client
7  SQL*Net roundtrips to/from client
0  sorts (memory)
0  sorts (disk)
90  rows processed
SQL> /
90 rows selected.
Elapsed: 00:00:00.76
Statistics
----------------------------------------------------------
13  recursive calls
0  db block gets
19518  consistent gets
0  physical reads
1856  redo size
4689  bytes sent via SQL*Net to client
455  bytes received via SQL*Net from client
7  SQL*Net roundtrips to/from client
0  sorts (memory)
0  sorts (disk)
90  rows processed
SQL> /
90 rows selected.
Elapsed: 00:00:00.37
Statistics
----------------------------------------------------------
13  recursive calls
0  db block gets
15409  consistent gets
0  physical reads
0  redo size
4689  bytes sent via SQL*Net to client
455  bytes received via SQL*Net from client
7  SQL*Net roundtrips to/from client
0  sorts (memory)
0  sorts (disk)
90  rows processed
SQL> /
90 rows selected.
Elapsed: 00:00:00.30
Statistics
----------------------------------------------------------
13  recursive calls
0  db block gets
20226  consistent gets
0  physical reads
64  redo size
4689  bytes sent via SQL*Net to client
455  bytes received via SQL*Net from client
7  SQL*Net roundtrips to/from client
0  sorts (memory)
0  sorts (disk)
90  rows processed
SQL> /
90 rows selected.
Elapsed: 00:00:00.32
Statistics
----------------------------------------------------------
13  recursive calls
0  db block gets
17881  consistent gets
0  physical reads
0  redo size
4689  bytes sent via SQL*Net to client
455  bytes received via SQL*Net from client
7  SQL*Net roundtrips to/from client
0  sorts (memory)
0  sorts (disk)
90  rows processed
SQL> /
90 rows selected.
Elapsed: 00:00:00.42
Statistics
----------------------------------------------------------
13  recursive calls
0  db block gets
15728  consistent gets
0  physical reads
0  redo size
4689  bytes sent via SQL*Net to client
455  bytes received via SQL*Net from client
7  SQL*Net roundtrips to/from client
0  sorts (memory)
0  sorts (disk)
90  rows processed
SQL> /
90 rows selected.
Elapsed: 00:00:00.49
Statistics
----------------------------------------------------------
13  recursive calls
0  db block gets
17406  consistent gets
0  physical reads
0  redo size
4689  bytes sent via SQL*Net to client
455  bytes received via SQL*Net from client
7  SQL*Net roundtrips to/from client
0  sorts (memory)
0  sorts (disk)
90  rows processed
SQL> /
90 rows selected.
Elapsed: 00:00:00.25
Statistics
----------------------------------------------------------
13  recursive calls
0  db block gets
16768  consistent gets
0  physical reads
128  redo size
4689  bytes sent via SQL*Net to client
455  bytes received via SQL*Net from client
7  SQL*Net roundtrips to/from client
0  sorts (memory)
0  sorts (disk)
90  rows processed
SQL> /
90 rows selected.
Elapsed: 00:00:00.40
Statistics
----------------------------------------------------------
13  recursive calls
0  db block gets
16515  consistent gets
0  physical reads
0  redo size
4689  bytes sent via SQL*Net to client
455  bytes received via SQL*Net from client
7  SQL*Net roundtrips to/from client
0  sorts (memory)
0  sorts (disk)
90  rows processed
SQL> /
90 rows selected.
Elapsed: 00:00:00.34
Statistics
----------------------------------------------------------
13  recursive calls
0  db block gets
16046  consistent gets
0  physical reads
0  redo size
4689  bytes sent via SQL*Net to client
455  bytes received via SQL*Net from client
7  SQL*Net roundtrips to/from client
0  sorts (memory)
0  sorts (disk)
90  rows processed
SQL> /
90 rows selected.
Elapsed: 00:00:00.34
Statistics
----------------------------------------------------------
13  recursive calls
0  db block gets
19300  consistent gets
0  physical reads
1856  redo size
4689  bytes sent via SQL*Net to client
455  bytes received via SQL*Net from client
7  SQL*Net roundtrips to/from client
0  sorts (memory)
0  sorts (disk)
90  rows processed
SQL> /
90 rows selected.
Elapsed: 00:00:02.92
Statistics
----------------------------------------------------------
13  recursive calls
0  db block gets
19860  consistent gets
0  physical reads
1216  redo size
4689  bytes sent via SQL*Net to client
455  bytes received via SQL*Net from client
7  SQL*Net roundtrips to/from client
0  sorts (memory)
0  sorts (disk)
90  rows processed
SQL> /
90 rows selected.
Elapsed: 00:00:00.45
Statistics
----------------------------------------------------------
13  recursive calls
0  db block gets
15569  consistent gets
0  physical reads
0  redo size
4689  bytes sent via SQL*Net to client
455  bytes received via SQL*Net from client
7  SQL*Net roundtrips to/from client
0  sorts (memory)
0  sorts (disk)
90  rows processed
SQL> /
90 rows selected.
Elapsed: 00:00:00.42
Statistics
----------------------------------------------------------
13  recursive calls
0  db block gets
15120  consistent gets
0  physical reads
0  redo size
4689  bytes sent via SQL*Net to client
455  bytes received via SQL*Net from client
7  SQL*Net roundtrips to/from client
0  sorts (memory)
0  sorts (disk)
90  rows processed
SQL> /
90 rows selected.
Elapsed: 00:00:00.21
Statistics
----------------------------------------------------------
13  recursive calls
0  db block gets
17201  consistent gets
0  physical reads
0  redo size
4689  bytes sent via SQL*Net to client
455  bytes received via SQL*Net from client
7  SQL*Net roundtrips to/from client
0  sorts (memory)
0  sorts (disk)
90  rows processed
SQL> /
90 rows selected.
Elapsed: 00:00:00.14
Statistics
----------------------------------------------------------
13  recursive calls
0  db block gets
18365  consistent gets
0  physical reads
384  redo size
4689  bytes sent via SQL*Net to client
455  bytes received via SQL*Net from client
7  SQL*Net roundtrips to/from client
0  sorts (memory)
0  sorts (disk)
90  rows processed
SQL> /
90 rows selected.
Elapsed: 00:00:00.59
Statistics
----------------------------------------------------------
13  recursive calls
0  db block gets
17998  consistent gets
0  physical reads
0  redo size
4689  bytes sent via SQL*Net to client
455  bytes received via SQL*Net from client
7  SQL*Net roundtrips to/from client
0  sorts (memory)
0  sorts (disk)
90  rows processed
SQL> /
90 rows selected.
Elapsed: 00:00:00.29
Statistics
----------------------------------------------------------
13  recursive calls
0  db block gets
14515  consistent gets
0  physical reads
0  redo size
4689  bytes sent via SQL*Net to client
455  bytes received via SQL*Net from client
7  SQL*Net roundtrips to/from client
0  sorts (memory)
0  sorts (disk)
90  rows processed
SQL> /
90 rows selected.
Elapsed: 00:00:00.11
Statistics
----------------------------------------------------------
13  recursive calls
0  db block gets
15595  consistent gets
0  physical reads
704  redo size
4689  bytes sent via SQL*Net to client
455  bytes received via SQL*Net from client
7  SQL*Net roundtrips to/from client
0  sorts (memory)
0  sorts (disk)
90  rows processed
SQL> /
90 rows selected.
Elapsed: 00:00:00.23
Statistics
----------------------------------------------------------
13  recursive calls
0  db block gets
15675  consistent gets
0  physical reads
768  redo size
4689  bytes sent via SQL*Net to client
455  bytes received via SQL*Net from client
7  SQL*Net roundtrips to/from client
0  sorts (memory)
0  sorts (disk)
90  rows processed
SQL> /
90 rows selected.
Elapsed: 00:00:00.20
Statistics
----------------------------------------------------------
13  recursive calls
0  db block gets
15584  consistent gets
0  physical reads
0  redo size
4689  bytes sent via SQL*Net to client
455  bytes received via SQL*Net from client
7  SQL*Net roundtrips to/from client
0  sorts (memory)
0  sorts (disk)
90  rows processed
SQL> /
90 rows selected.
Elapsed: 00:00:00.14
Statistics
----------------------------------------------------------
13  recursive calls
0  db block gets
18380  consistent gets
0  physical reads
1344  redo size
4689  bytes sent via SQL*Net to client
455  bytes received via SQL*Net from client
7  SQL*Net roundtrips to/from client
0  sorts (memory)
0  sorts (disk)
90  rows processed

从上面的测试不难看出,对于DML操作频繁的话,对全文索引来说,还是有较大的影响的。

SQL> begin
2    for i in 1 .. 15000 loop
3      if mod(i, 2) = 0 then
4        update docs
5           set owner = 'google'
6         where id = i
7           and id > 50000
8           and id < 10000;
9        commit;
10      end if;
11    end loop;
12    commit;
13  end;
14  /
PL/SQL procedure successfully completed.
Elapsed: 00:00:02.25
SQL> exec ctx_ddl.optimize_index('idx_docs','rebuild') ;
PL/SQL procedure successfully completed.
Elapsed: 00:00:02.84
SQL> begin
2    for i in 1 .. 15000 loop
3      if mod(i, 2) = 0 then
4        update docs
5           set owner = 'baidu'
6         where id = i
7           and id > 50000
8           and id < 10000;
9        commit;
10      end if;
11    end loop;
12    commit;
13  end;
14  /
PL/SQL procedure successfully completed.
Elapsed: 00:00:02.23
SQL> exec ctx_ddl.optimize_index('idx_docs','FULL') ;
PL/SQL procedure successfully completed.
Elapsed: 00:00:00.45
SQL> begin
2  for i in 1..10000 loop
3  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/');
4  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=210');
5  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=216');
6  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=201');
7  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=196');
8  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=219');
9  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=205');
10  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=206');
11  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=207');
12  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=199');
13  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=208');
14  commit;
15  end loop;
16  end;
17  /
begin
*
ERROR at line 1:
ORA-29875: failed in the execution of the ODCIINDEXINSERT routine
ORA-20000: Oracle Text error:
DRG-50857: oracle error in textindexmethods.ODCIIndexInsert
ORA-00604: error occurred at recursive SQL level 2
ORA-01013: user requested cancel of current operation
ORA-06512: at "CTXSYS.DRUE", line 160
ORA-06512: at "CTXSYS.TEXTINDEXMETHODS", line 633
ORA-06512: at line 13
Elapsed: 00:01:09.73
SQL> select count(*) from docs;
COUNT(*)
----------
138898
Elapsed: 00:00:00.35
SQL> exec ctx_ddl.optimize_index('idx_docs','FULL') ;
PL/SQL procedure successfully completed.
Elapsed: 00:00:00.48
SQL> begin
2  for i in 1..10000 loop
3  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/');
4  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=210');
5  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=216');
6  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=201');
7  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=196');
8  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=219');
9  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=205');
10  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=206');
11  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=207');
12  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=199');
13  INSERT INTO docs(id, text) VALUES(seq_docs.NEXTVAL, 'http://www.killdb.com/?p=208');
14  commit;
15  end loop;
16  end;
17  /
begin
*
ERROR at line 1:
ORA-29875: failed in the execution of the ODCIINDEXINSERT routine
ORA-20000: Oracle Text error:
DRG-50857: oracle error in textindexmethods.ODCIIndexInsert
ORA-01013: user requested cancel of current operation
ORA-06512: at "CTXSYS.DRUE", line 160
ORA-06512: at "CTXSYS.TEXTINDEXMETHODS", line 633
ORA-06512: at line 12
Elapsed: 00:01:06.17
SQL> exec ctx_ddl.optimize_index('idx_docs','rebuild') ;
PL/SQL procedure successfully completed.
Elapsed: 00:00:02.09
SQL> select count(*) from docs;
COUNT(*)
----------
156091
Elapsed: 00:00:00.01

有人说优化index的时候,使用rebuild比full快很多,但是我测试恰恰相反,不知道为啥。

最后总结下:

1. DML操作较为频繁表,对全文索引一定影响,但是如果说必须使用该功能,那么也没办法,
2. 至于说为什么有一定影响,其实原理都一样的,因为逻辑读的消耗会增加,必然影响性能。

该功能是从oracle 9i引入的,10g,11g都分别有一定的改变,下一篇文章将会进行描述。


评论

  1. 这篇文章 是不是漏了建索引这一步:)

     CREATE INDEX IDX_DOCS ON docs(text) INDEXTYPE IS CTXSYS.CONTEXT;

  2. 看的很仔细 确实是漏了。。。

  3. Thank you for the post

发表回复

您的电子邮箱地址不会被公开。 必填项已用 * 标注