Skip to Main Content
  • Questions
  • Rebuild optimize failing for Text index in RDBMS 12c (12.1.0.2.0) CDB-PDB config

Breadcrumb

Question and Answer

Connor McDonald

Thanks for the question, Sagar.

Asked: July 13, 2016 - 6:32 pm UTC

Last updated: July 14, 2016 - 9:35 am UTC

Version: 12.1.0.2.0

Viewed 1000+ times

You Asked

Hi Guys,

DB: Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production
OS: OEL 6.5

I am testing use case for Oracle Text index on 12c CDB-PDB config (single PDB), and found that REBUILD optimize is failing with internal exception for the text index. However, FAST optimize is successfully running.
Could you look into this and advice further.

--------------------------
-- Create table TEXT_TAB
--------------------------
CREATE TABLE text_tab
 ( 
  "id"  NUMBER NOT NULL ENABLE, 
  "type"  VARCHAR2(200 CHAR) NOT NULL ENABLE, 
  "text_col" VARCHAR2(4000 CHAR), 
  "category" VARCHAR2(30) NOT NULL ENABLE, 
  CONSTRAINT "text_tab_pk" PRIMARY KEY ("id")
 );


--------------------------
-- Create Preference
--------------------------
BEGIN
 ctx_ddl.create_preference ('TEXT_TAB_PREF','world_lexer');
END;
/


--------------------------------
-- Create Text Index TEXT_IND
--------------------------------
BEGIN
 EXECUTE IMMEDIATE 'CREATE INDEX text_ind ON text_tab(text_col) INDEXTYPE IS CTXSYS.CONTEXT ONLINE FILTER BY category PARAMETERS('' SYNC (ON COMMIT) LEXER TEXT_TAB_PREF'')';
END;
/


--------------------------------
-- REBUILD Optimize Text Index
--------------------------------
BEGIN
  ctx_ddl.optimize_index('TEXT_IND','REBUILD');
END;
/

Error report -
ORA-20000: Oracle Text error:
DRG-50857: oracle error in drftoptrebxch
ORA-14097: column type or size mismatch in ALTER TABLE EXCHANGE PARTITION

ORA-06512: at "CTXSYS.DRUE", line 160
ORA-06512: at "CTXSYS.CTX_DDL", line 1161
ORA-06512: at line 1
*Cause:    The stored procedure 'raise_application_error'
    was called which causes this error to be generated.
*Action:   Correct the problem as described in the error message or contact
    the application administrator or DBA for more information.


--------------------------------
-- FAST Optimize Text Index
--------------------------------
BEGIN
  ctx_ddl.optimize_index('TEXT_IND','REBUILD');
END;
/

Successfully Completed



Thanks in advance...

and Connor said...

I can't reproduce your error, using either mixed case or upper case columns (your test case didnt work, so I made some assumptions)

SQL> CREATE TABLE text_tab
  2   (
  3    "ID"  NUMBER NOT NULL ENABLE,
  4    "TYPE"  VARCHAR2(200 CHAR) NOT NULL ENABLE,
  5    "TEXT_COL" VARCHAR2(4000 CHAR),
  6    "CATEGORY" VARCHAR2(30) NOT NULL ENABLE,
  7    CONSTRAINT "text_tab_pk" PRIMARY KEY ("ID")
  8   );

Table created.

SQL>
SQL> exec  ctx_ddl.drop_preference ('TEXT_TAB_PREF');

PL/SQL procedure successfully completed.

SQL> exec ctx_ddl.create_preference ('TEXT_TAB_PREF','world_lexer');

PL/SQL procedure successfully completed.

SQL>
SQL> CREATE INDEX text_ind ON text_tab(text_col) INDEXTYPE IS CTXSYS.CONTEXT ONLINE FILTER BY category PARAMETERS(' SYNC (ON COMMIT) LEXER TEXT_TAB_PREF');

Index created.

SQL>
SQL> exec  ctx_ddl.optimize_index('TEXT_IND','REBUILD');

PL/SQL procedure successfully completed.

=====================================

SQL> drop table text_tab purge;

Table dropped.

SQL>
SQL> CREATE TABLE text_tab
  2   (
  3    "id"  number not null enable,
  4    "type"  varchar2(200 char) not null enable,
  5    "text_col" varchar2(4000 char),
  6    "category" varchar2(30) not null enable,
  7    constraint "text_tab_pk" primary key ("id")
  8   );

Table created.

SQL>
SQL> exec  ctx_ddl.drop_preference ('TEXT_TAB_PREF');

PL/SQL procedure successfully completed.

SQL> exec ctx_ddl.create_preference ('TEXT_TAB_PREF','world_lexer');

PL/SQL procedure successfully completed.

SQL>
SQL> CREATE INDEX text_ind ON text_tab("text_col") INDEXTYPE IS CTXSYS.CONTEXT ONLINE FILTER BY "category" PARAMETERS(' SYNC (ON COMMIT) LEXER TEXT_TAB_PREF');

Index created.

SQL>
SQL> exec  ctx_ddl.optimize_index('TEXT_IND','REBUILD');

PL/SQL procedure successfully completed.





But there are some notes on MOS about this error and patches available for it, so probably best to have a chat with Support.

Rating

  (2 ratings)

Is this answer out of date? If it is, please let us know via a Comment

Comments

Sagar Dua, July 14, 2016 - 6:06 am UTC

Chris,

Thanks for the response.
Apologies, I copied wrong table DDL, your version is the correct one.

My issue stands, get same exception post running REBUILD optimize.

CREATE TABLE text_tab
 ( 
  "ID"  NUMBER NOT NULL ENABLE, 
  "TYPE"  VARCHAR2(200 CHAR) NOT NULL ENABLE, 
  "TEXT_COL" VARCHAR2(4000 CHAR), 
  "CATEGORY" VARCHAR2(30) NOT NULL ENABLE, 
  CONSTRAINT "TEXT_TAB_PK" PRIMARY KEY ("ID")
 );
 
Table created.

BEGIN
 ctx_ddl.create_preference ('TEXT_TAB_PREF','world_lexer');
END;
/

PL/SQL procedure successfully completed.

BEGIN
 EXECUTE IMMEDIATE 'CREATE INDEX text_ind ON text_tab(text_col) INDEXTYPE IS CTXSYS.CONTEXT ONLINE FILTER BY CATEGORY PARAMETERS('' SYNC (ON COMMIT) LEXER TEXT_TAB_PREF'')';
END;
/

Index created.

SELECT object_name, status FROM user_objects WHERE object_name LIKE 'DR$%' AND object_name LIKE '%TEXT_IND%';

OBJECT_NAME        STATUS
------------------ -------
DR$TEXT_IND$X      VALID  
DR$TEXT_IND$S      VALID  
DR$TEXT_IND$R      VALID  
DR$TEXT_IND$N      VALID  
DR$TEXT_IND$K      VALID  
DR$TEXT_IND$I      VALID  

SELECT index_name,table_name,status, parameters, domidx_status,domidx_opstatus FROM user_indexes WHERE index_type='DOMAIN' AND index_name='TEXT_IND';

INDEX_NAME     TABLE_NAME      STATUS   PARAMETERS                              DOMIDX_STATU DOMIDX
-------------- --------------- -------- --------------------------------------- ------------ ------
TEXT_IND       TEXT_TAB        VALID     SYNC (ON COMMIT) LEXER TEXT_TAB_PREF   VALID        VALID 

BEGIN
  ctx_ddl.optimize_index('TEXT_IND','REBUILD');
END;
/

Error report -
ORA-20000: Oracle Text error:
DRG-50857: oracle error in drftoptrebxch
ORA-14097: column type or size mismatch in ALTER TABLE EXCHANGE PARTITION

ORA-06512: at "CTXSYS.DRUE", line 160
ORA-06512: at "CTXSYS.CTX_DDL", line 1161
ORA-06512: at line 2
20000. 00000 -  "%s"
*Cause:    The stored procedure 'raise_application_error'
           was called which causes this error to be generated.
*Action:   Correct the problem as described in the error message or contact
           the application administrator or DBA for more information.

-- Run from SYS schema
SELECT * FROM dba_objects WHERE status!='VALID';

no rows


Search in the MoS as well for "DRG-50857: oracle error in drftoptrebxch", and found below links matching the exception scenario, but both do not apply to my environment.

1) https://support.oracle.com/epmos/faces/DocumentDisplay?id=1939574.1&displayIndex=1#SYMPTOM
2) https://support.oracle.com/epmos/faces/DocumentDisplay?id=2075722.1&displayIndex=2#SYMPTOM

Any pointers?

Thanks...
Connor McDonald
July 14, 2016 - 9:35 am UTC

It was Connor who answered, but hey ;)

Your example works for me too:

SQL> CREATE TABLE text_tab
  2   (
  3    "ID"  NUMBER NOT NULL ENABLE,
  4    "TYPE"  VARCHAR2(200 CHAR) NOT NULL ENABLE,
  5    "TEXT_COL" VARCHAR2(4000 CHAR),
  6    "CATEGORY" VARCHAR2(30) NOT NULL ENABLE,
  7    CONSTRAINT "TEXT_TAB_PK" PRIMARY KEY ("ID")
  8   );

Table created.

SQL>
SQL> BEGIN
  2   ctx_ddl.create_preference ('TEXT_TAB_PREF','world_lexer');
  3  END;
  4  /

PL/SQL procedure successfully completed.

SQL>
SQL> BEGIN
  2   EXECUTE IMMEDIATE 'CREATE INDEX text_ind ON text_tab(text_col) INDEXTYPE IS CTXSYS.CONTEXT ONLINE FILTER BY CATEGORY PARAMETERS('' SYNC (ON COMMIT) LEXER
TEXT_TAB_PREF'')';
  3  END;
  4  /

PL/SQL procedure successfully completed.

SQL>
SQL> BEGIN
  2    ctx_ddl.optimize_index('TEXT_IND','REBUILD');
  3  END;
  4  /

PL/SQL procedure successfully completed.


I think you're going to have to take this up with Support.

Chris

Sagar Dua, July 14, 2016 - 9:50 am UTC

Thanks Chris and Connor for followup :)
Yes, I have started a conversation on the same with Support.

More to Explore

PL/SQL demos

Check out more PL/SQL tutorials on our LiveSQL tool.

PL/SQL docs

PL/SQL reference manual from the Oracle documentation library