Fixing Error: InnoDB: (Duplicate key) writing word node to FTS auxiliary index table.
This error appears in your error log. It means there is a duplicate key in your full text index, sadly it doesn’t tell you which table or which full text index.
HINT for MySQL/MariaDB/Percona devs: just add the index_id to the error message.
SQL to find all text indexes in your db:
select table_schema,table_name,index_name, index_type from information_schema.statistics where index_type = 'FULLTEXT' order by table_schema; +-----------------+-----------------------+-------------+------------+ | table_schema | table_name | index_name | index_type | +-----------------+-----------------------+-------------+------------+ | db0001_fullname | Activity_fullname_log | message | FULLTEXT | | db0002_fullname | Activity_fullname_log | message | FULLTEXT | +-----------------+-----------------------+-------------+------------+ 2 rows in set (0.715 sec)
So what is the next step?
If you follow the documentation it will tell you to rebuild the table or use OPTIMIZE TABLE with innodb_optimize_fulltext_only=ON to rebuild just the text index.
https://dev.mysql.com/doc/refman/8.0/en/fulltext-fine-tuning.html#fulltext-rebuild-innodb-indexes
https://dev.mysql.com/doc/refman/8.0/en/fulltext-fine-tuning.html#fulltext-optimize
My recommendation: Rebuild the table (including the full text indexes)
-- Plain old ALTER TABLE use db0001_fullname; ALTER ONLINE TABLE Activity_fullname_log ENGINE=INNODB;
-- Or pt-osc equivalent pt-online-schema-change --dry-run --alter="ENGINE=INNODB" \ --alter-foreign-keys-method=rebuild_constraints --max-lag=60 \ --max-load Threads_running=50 --critical-load Threads_running=60 \ h=localhost,D=db0001_fullname,t=Activity_fullname_log pt-online-schema-change --execute --alter="ENGINE=INNODB" \ --alter-foreign-keys-method=rebuild_constraints --max-lag=60 \ --max-load Threads_running=50 --critical-load Threads_running=60 \ h=localhost,D=db0001_fullname,t=Activity_fullname_log
The OPTIMIZE TABLE method:
The trouble with this method is it will only do a set number of words per execution of OPTIMIZE TABLE.
SQL to set the specific table so you can query INNODB_FT_INDEX_TABLE
set global innodb_ft_aux_table = 'db0001_fullname/Activity_fullname_log'; Query OK, 0 rows affected (0.002 sec)
SQL to find the number of distinct words in a specific text index:
SELECT count(distinct word) FROM INFORMATION_SCHEMA.INNODB_FT_INDEX_TABLE; +----------------------+ | count(distinct word) | +----------------------+ | 600000 | +----------------------+ 1 row in set (1 min 53.333 sec)
Depending how much impact you want per OPTIMIZE TABLE set innodb_ft_num_word_optimize appropriately.
The remaining steps to rebuilding your full text index using OPTIMIZE TABLE
set GLOBAL innodb_ft_num_word_optimize=10000; set GLOBAL innodb_optimize_fulltext_only=ON; OPTIMIZE TABLE Activity_fullname_log; OPTIMIZE TABLE Activity_fullname_log; OPTIMIZE TABLE Activity_fullname_log; OPTIMIZE TABLE Activity_fullname_log; OPTIMIZE TABLE Activity_fullname_log; ... -- repeat round(distinct words/innodb_ft_num_word_optimize)+1 OPTIMIZE TABLE Activity_fullname_log;
No comments:
Post a Comment
Note: only a member of this blog may post a comment.