mirror of
https://github.com/MariaDB/server.git
synced 2025-02-07 06:12:18 +01:00
![Aleksey Midenkov](/assets/img/avatar_default.png)
1. In case of system-versioned table add row_end into FTS_DOC_ID index in fts_create_common_tables() and innobase_create_key_defs(). fts_n_uniq() returns 1 or 2 depending on whether the table is system-versioned. After this patch recreate of FTS_DOC_ID index is required for existing system-versioned tables. If you see this message in error log or server warnings: "InnoDB: Table db/t1 contains 2 indexes inside InnoDB, which is different from the number of indexes 1 defined in the MariaDB" use this command to fix the table: ALTER TABLE db.t1 FORCE; 2. Fix duplicate history for secondary unique index like it was done in MDEV-23644 for clustered index (932ec586aa
). In case of existing history row which conflicts with currently inseted row we check in row_ins_scan_sec_index_for_duplicate() whether that row was inserted as part of current transaction. In that case we indicate with DB_FOREIGN_DUPLICATE_KEY that new history row is not needed and should be silently skipped. 3. Some parts of MDEV-21138 (7410ff436e
) reverted. Skipping of FTS_DOC_ID index for history rows made problems with purge system. Now this is fixed differently by p.2. 4. wait_all_purged.inc checks that we didn't affect non-history rows so they are deleted and purged correctly. Additional FTS fixes fts_init_get_doc_id(): exclude history rows from max_doc_id calculation. fts_init_get_doc_id() callback is used only for crash recovery. fts_add_doc_by_id(): set max value for row_end field. fts_read_stopword(): stopwords table can be system-versioned too. We now read stopwords only for current data. row_insert_for_mysql(): exclude history rows from doc_id validation. row_merge_read_clustered_index(): exclude history_rows from doc_id processing. fts_load_user_stopword(): for versioned table retrieve row_end field and skip history rows. For non-versioned table we retrieve 'value' field twice (just for uniformity). FTS tests for System Versioning now include maybe_versioning.inc which adds 3 combinations: 'vers' for debug build sets sysvers_force and sysvers_hide. sysvers_force makes every created table system-versioned, sysvers_hide hides WITH SYSTEM VERSIONING for SHOW CREATE. Note: basic.test, stopword.test and versioning.test do not require debug for 'vers' combination. This is controlled by $modify_create_table in maybe_versioning.inc and these tests run WITH SYSTEM VERSIONING explicitly which allows to test 'vers' combination on non-debug builds. 'vers_trx' like 'vers' sets sysvers_force_trx and sysvers_hide. That tests FTS with trx_id-based System Versioning. 'orig' works like before: no System Versioning is added, no debug is required. Upgrade/downgrade test for System Versioning is done by innodb_fts.versioning. It has 2 combinations: 'prepare' makes binaries in std_data (requires old server and OLD_BINDIR). It tests upgrade/downgrade against old server as well. 'upgrade' tests upgrade against binaries in std_data. Cleanups: Removed innodb-fts-stopword.test as it duplicates stopword.test
134 lines
4.6 KiB
Text
134 lines
4.6 KiB
Text
#
|
|
# Test for bug from Jean-Cédric COSTA <jean-cedric.costa@ensmp.fr>
|
|
#
|
|
--source include/have_innodb.inc
|
|
--source include/maybe_versioning.inc
|
|
|
|
--disable_warnings
|
|
drop table if exists t1, t2;
|
|
--enable_warnings
|
|
|
|
CREATE TABLE t1 (
|
|
id VARCHAR(255) NOT NULL PRIMARY KEY,
|
|
sujet VARCHAR(255),
|
|
motsclefs TEXT,
|
|
texte MEDIUMTEXT,
|
|
FULLTEXT(sujet, motsclefs, texte)
|
|
) ENGINE = InnoDB;
|
|
|
|
INSERT INTO t1 VALUES('123','toto','essai','test');
|
|
INSERT INTO t1 VALUES('456','droit','penal','lawyer');
|
|
INSERT INTO t1 VALUES('789','aaaaa','bbbbb','cccccc');
|
|
|
|
CREATE TABLE t2 (
|
|
id VARCHAR(255) NOT NULL,
|
|
author VARCHAR(255) NOT NULL
|
|
) ENGINE = InnoDB;
|
|
|
|
INSERT INTO t2 VALUES('123', 'moi');
|
|
INSERT INTO t2 VALUES('123', 'lui');
|
|
INSERT INTO t2 VALUES('456', 'lui');
|
|
|
|
-- disable_result_log
|
|
ANALYZE TABLE t1;
|
|
ANALYZE TABLE t2;
|
|
-- enable_result_log
|
|
|
|
select round(match(t1.texte,t1.sujet,t1.motsclefs) against('droit'),5)
|
|
from t1 left join t2 on t2.id=t1.id;
|
|
select match(t1.texte,t1.sujet,t1.motsclefs) against('droit' IN BOOLEAN MODE)
|
|
from t1 left join t2 on t2.id=t1.id;
|
|
|
|
drop table t1, t2;
|
|
|
|
#
|
|
# BUG#484, reported by Stephen Brandon <stephen@brandonitconsulting.co.uk>
|
|
#
|
|
|
|
create table t1 (venue_id int(11) default null, venue_text varchar(255) default null, dt datetime default null) ENGINE = InnoDB;
|
|
|
|
insert into t1 (venue_id, venue_text, dt) values (1, 'a1', '2003-05-23 19:30:00'),(null, 'a2', '2003-05-23 19:30:00');
|
|
eval create table t2 (name varchar(255) not null default '', entity_id int(11) not null auto_increment, primary key (entity_id), fulltext key name (name)) engine= innodb;
|
|
insert into t2 (name, entity_id) values ('aberdeen town hall', 1), ('glasgow royal concert hall', 2), ('queen\'s hall, edinburgh', 3);
|
|
-- disable_result_log
|
|
ANALYZE TABLE t1;
|
|
ANALYZE TABLE t2;
|
|
-- enable_result_log
|
|
select * from t1 left join t2 on venue_id = entity_id where match(name) against('aberdeen' in boolean mode) and dt = '2003-05-23 19:30:00';
|
|
select * from t1 left join t2 on venue_id = entity_id where match(name) against('aberdeen') and dt = '2003-05-23 19:30:00';
|
|
select * from t1 left join t2 on (venue_id = entity_id and match(name) against('aberdeen' in boolean mode)) where dt = '2003-05-23 19:30:00';
|
|
select * from t1 left join t2 on (venue_id = entity_id and match(name) against('aberdeen')) where dt = '2003-05-23 19:30:00';
|
|
drop table t1,t2;
|
|
|
|
#
|
|
# BUG#14708
|
|
# Inconsistent treatment of NULLs in LEFT JOINed FULLTEXT matching without index
|
|
#
|
|
|
|
create table t1 (id int not null primary key, d char(200) not null, e char(200), fulltext (d, e)) ENGINE = InnoDB;
|
|
insert into t1 values (1, 'aword', null), (2, 'aword', 'bword'), (3, 'bword', null), (4, 'bword', 'aword'), (5, 'aword and bword', null);
|
|
-- disable_result_log
|
|
ANALYZE TABLE t1;
|
|
-- enable_result_log
|
|
select * from t1 where match(d, e) against ('+aword +bword' in boolean mode);
|
|
|
|
# INNODB_FTS: Investigate Full Text search on joined result
|
|
create table t2 (m_id int not null, f char(200), key (m_id), fulltext (f)) engine = InnoDB;
|
|
insert into t2 values (1, 'bword'), (3, 'aword'), (5, '');
|
|
-- disable_result_log
|
|
ANALYZE TABLE t2;
|
|
-- enable_result_log
|
|
--error ER_WRONG_ARGUMENTS
|
|
select * from t1 left join t2 on m_id = id where match(d, e, f) against ('+aword +bword' in boolean mode);
|
|
drop table t1,t2;
|
|
|
|
#
|
|
# BUG#25637: LEFT JOIN with BOOLEAN FULLTEXT loses left table matches
|
|
# (this is actually the same bug as bug #14708)
|
|
#
|
|
|
|
CREATE TABLE t1 (
|
|
id int(10) NOT NULL auto_increment,
|
|
link int(10) default NULL,
|
|
name mediumtext default NULL,
|
|
PRIMARY KEY (id),
|
|
FULLTEXT (name)
|
|
) ENGINE = InnoDB;
|
|
INSERT INTO t1 VALUES (1, 1, 'string');
|
|
INSERT INTO t1 VALUES (2, 0, 'string');
|
|
CREATE TABLE t2 (
|
|
id int(10) NOT NULL auto_increment,
|
|
name mediumtext default NULL,
|
|
PRIMARY KEY (id),
|
|
FULLTEXT (name)
|
|
) ENGINE = InnoDB;
|
|
INSERT INTO t2 VALUES (1, 'string');
|
|
|
|
-- disable_result_log
|
|
ANALYZE TABLE t1;
|
|
ANALYZE TABLE t2;
|
|
-- enable_result_log
|
|
|
|
--error ER_WRONG_ARGUMENTS
|
|
SELECT t1.*, MATCH(t1.name) AGAINST('string') AS relevance
|
|
FROM t1 LEFT JOIN t2 ON t1.link = t2.id
|
|
WHERE MATCH(t1.name, t2.name) AGAINST('string' IN BOOLEAN MODE);
|
|
|
|
DROP TABLE t1,t2;
|
|
|
|
# End of 4.1 tests
|
|
|
|
#
|
|
# BUG#25729 - boolean full text search is confused by NULLs produced by LEFT
|
|
# JOIN
|
|
#
|
|
CREATE TABLE t1 (a INT) ENGINE = InnoDB;
|
|
CREATE TABLE t2 (b INT, c TEXT, KEY(b), FULLTEXT(c)) ENGINE = InnoDB;
|
|
INSERT INTO t1 VALUES(1);
|
|
INSERT INTO t2(b,c) VALUES(2,'castle'),(3,'castle');
|
|
-- disable_result_log
|
|
ANALYZE TABLE t1;
|
|
ANALYZE TABLE t2;
|
|
-- enable_result_log
|
|
SELECT * FROM t1 LEFT JOIN t2 ON a=b WHERE MATCH(c) AGAINST('+castle' IN BOOLEAN MODE);
|
|
DROP TABLE t1, t2;
|