mariadb/mysql-test/suite/innodb_fts/t/basic.inc
Aleksey Midenkov e056efdd6c MDEV-25004 Missing row in FTS_DOC_ID_INDEX during DELETE HISTORY
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
2022-12-27 00:02:02 +03:00

264 lines
8.6 KiB
SQL

if ($basic_stage == create_table)
{
# Create FTS table
--error ER_INNODB_NO_FT_TEMP_TABLE
CREATE TEMPORARY TABLE articles (
id INT UNSIGNED AUTO_INCREMENT NOT NULL PRIMARY KEY,
title VARCHAR(200),
body TEXT,
FULLTEXT (title,body)
) ENGINE=InnoDB;
--disable_query_log
eval CREATE TABLE articles (
id INT UNSIGNED AUTO_INCREMENT NOT NULL PRIMARY KEY,
title VARCHAR(200),
body TEXT,
FULLTEXT (title,body)
)$create_options ENGINE=InnoDB;
--enable_query_log
}
if ($basic_stage == insert_1)
{
# Insert six rows
INSERT INTO articles (title,body) VALUES
('MySQL Tutorial','DBMS stands for DataBase ...') ,
('How To Use MySQL Well','After you went through a ...'),
('Optimizing MySQL','In this tutorial we will show ...'),
('1001 MySQL Tricks','1. Never run mysqld as root. 2. ...'),
('MySQL vs. YourSQL','In the following database comparison ...'),
('MySQL Security','When configured properly, MySQL ...');
}
if ($basic_stage == select_1)
{
# Look for 'Database' in table article
SELECT * FROM articles
WHERE MATCH (title,body)
AGAINST ('Database' IN NATURAL LANGUAGE MODE);
SELECT COUNT(*) FROM articles
WHERE MATCH (title,body)
AGAINST ('database' IN NATURAL LANGUAGE MODE);
SELECT * FROM articles
WHERE MATCH (title, body)
AGAINST ('Tutorial' IN NATURAL LANGUAGE MODE);
SELECT COUNT(IF(MATCH (title,body)
AGAINST ('database' IN NATURAL LANGUAGE MODE), 1, NULL))
AS count FROM articles;
# Select Relevance Ranking
SELECT id, body, MATCH (title,body)
AGAINST ('Database' IN NATURAL LANGUAGE MODE) AS score
FROM articles;
# 'MySQL' treated as stopword (stopword functionality not yet supported)
SELECT * FROM articles
WHERE MATCH (title,body)
AGAINST ('MySQL' IN NATURAL LANGUAGE MODE);
# Boolean search
# Select rows contain "MySQL" but not "YourSQL"
SELECT * FROM articles WHERE MATCH (title,body)
AGAINST ('+MySQL -YourSQL' IN BOOLEAN MODE);
# Select rows contain at least one of the two words
SELECT * FROM articles WHERE MATCH (title,body)
AGAINST ('DBMS Security' IN BOOLEAN MODE);
# Select rows contain both "MySQL" and "YourSQL"
SELECT * FROM articles WHERE MATCH (title,body)
AGAINST ('+MySQL +YourSQL' IN BOOLEAN MODE);
# Select rows contain "MySQL" but rank rows with "YourSQL" higher
SELECT * FROM articles WHERE MATCH (title,body)
AGAINST ('+MySQL YourSQL' IN BOOLEAN MODE);
# Test negation operator. Select rows contain MySQL,
# if the row contains "YourSQL", rank it lower
SELECT * FROM articles WHERE MATCH (title,body)
AGAINST ('+MySQL ~YourSQL' IN BOOLEAN MODE);
# Test wild card search operator
# Notice row with "the" will not get fetched due to
# stopword filtering
SELECT * FROM articles WHERE MATCH (title,body)
AGAINST ('t*' IN BOOLEAN MODE);
# Test wild card search, notice row 6 with 2 "MySQL" rank first
SELECT * FROM articles WHERE MATCH (title,body)
AGAINST ('MY*' IN BOOLEAN MODE);
# Another wild card search
SELECT * FROM articles WHERE MATCH (title,body)
AGAINST ('ru*' IN BOOLEAN MODE);
# Test ">" and "<" Operator, the ">" operator increases
# the word relevance rank and the "<" operator decreases it
# Following test puts rows with "Well" on top and rows
# with "stands" at the bottom
SELECT * FROM articles WHERE MATCH (title,body)
AGAINST ('+ MySQL >Well < stands' IN BOOLEAN MODE);
# Test sub-expression boolean search. Find rows contain
# "MySQL" but not "Well" or "stands".
SELECT * FROM articles WHERE MATCH (title,body)
AGAINST ('+ MySQL - (Well stands)' IN BOOLEAN MODE);
--error 128
SELECT * FROM articles WHERE MATCH (title,body) AGAINST
('(((((((((((((((((((((((((((((((((Security)))))))))))))))))))))))))))))))))'
IN BOOLEAN MODE);
SELECT * FROM articles WHERE MATCH (title,body) AGAINST
('((((((((((((((((((((((((((((((((Security))))))))))))))))))))))))))))))))'
IN BOOLEAN MODE);
SELECT * FROM articles WHERE MATCH (title,body) AGAINST
('(((((((((((((((((((((((((((((((vs))))))))))))))))))))))))))))))),(((to)))'
IN BOOLEAN MODE);
--error ER_PARSE_ERROR
SELECT * FROM articles WHERE MATCH (title,body) AGAINST
('((((((((((((((((((((((((((((((((Security)))))))))))))))))))))))))))))))'
IN BOOLEAN MODE);
--error ER_PARSE_ERROR
SELECT * FROM articles WHERE MATCH (title,body) AGAINST
('(((((((((((((((((((((((((((((((((Security))))))))))))))))))))))))))))))))'
IN BOOLEAN MODE);
# Test sub-expression boolean search. Find rows contain
# "MySQL" and "Well" or "MySQL" and "stands". But rank the
# doc with "Well" higher, and doc with "stands" lower.
SELECT * FROM articles WHERE MATCH (title,body)
AGAINST ('+ MySQL + (>Well < stands)' IN BOOLEAN MODE);
# Test nested sub-expression.
SELECT * FROM articles WHERE MATCH (title,body)
AGAINST ('YourSQL + (+MySQL - (Tricks Security))' IN BOOLEAN MODE);
# Find rows with "MySQL" but not "Tricks", "Security" nor "YourSQL"
SELECT * FROM articles WHERE MATCH (title,body)
AGAINST ('(+MySQL - (Tricks Security)) - YourSQL' IN BOOLEAN MODE);
# Test non-word delimiter combined with negate "-" operator
# This should return the same result as 'mysql - (Security DBMS)'
SELECT * FROM articles WHERE MATCH (title,body) AGAINST ('mysql - Security&DBMS' IN BOOLEAN MODE);
SELECT * FROM articles WHERE MATCH (title,body) AGAINST ('mysql - (Security DBMS)' IN BOOLEAN MODE);
# Again, the operator sequence should not matter
SELECT * FROM articles WHERE MATCH (title,body) AGAINST (' - Security&DBMS + YourSQL' IN BOOLEAN MODE);
SELECT * FROM articles WHERE MATCH (title,body) AGAINST ('+YourSQL - Security&DBMS' IN BOOLEAN MODE);
# Test query expansion
SELECT COUNT(*) FROM articles
WHERE MATCH (title,body)
AGAINST ('database' WITH QUERY EXPANSION);
}
if ($basic_stage == insert_2)
{
INSERT INTO articles (title,body) VALUES
('test query expansion','for database ...');
}
if ($basic_stage == select_2)
{
# This query will return result containing word "database" as
# the query expand from "test" to words in document just
# inserted above
SELECT * FROM articles
WHERE MATCH (title,body)
AGAINST ('test' WITH QUERY EXPANSION);
# This is to test the proximity search, search two word
# "following" and "comparison" within 19 character space
SELECT * FROM articles
WHERE MATCH (title,body)
AGAINST ('"following comparison"@3' IN BOOLEAN MODE);
# This is to test the proximity search, search two word
# "following" and "comparison" within 19 character space
# This search should come with no return result
SELECT * FROM articles
WHERE MATCH (title,body)
AGAINST ('"following comparison"@2' IN BOOLEAN MODE);
# This is to test the phrase search, searching phrase
# "following database"
SELECT * FROM articles
WHERE MATCH (title,body)
AGAINST ('"following database"' IN BOOLEAN MODE);
}
if ($basic_stage == insert_3)
{
# Insert into table with similar word of different distances
INSERT INTO articles (title,body) VALUES
('test proximity search, test, proximity and phrase',
'search, with proximity innodb');
INSERT INTO articles (title,body) VALUES
('test my proximity fts new search, test, proximity and phrase',
'search, with proximity innodb');
INSERT INTO articles (title,body) VALUES
('test more of proximity fts search, test, more proximity and phrase',
'search, with proximity innodb');
}
if ($basic_stage == select_3)
{
# This should only return the first document
SELECT * FROM articles
WHERE MATCH (title,body)
AGAINST ('"proximity search"@3' IN BOOLEAN MODE);
# This would return no document
SELECT * FROM articles
WHERE MATCH (title,body)
AGAINST ('"proximity search"@2' IN BOOLEAN MODE);
# This give you all three documents
SELECT * FROM articles
WHERE MATCH (title,body)
AGAINST ('"proximity search"@5' IN BOOLEAN MODE);
# Similar boundary testing for the words
SELECT * FROM articles
WHERE MATCH (title,body)
AGAINST ('"test proximity"@5' IN BOOLEAN MODE);
# No document will be returned
SELECT * FROM articles
WHERE MATCH (title,body)
AGAINST ('"test proximity"@1' IN BOOLEAN MODE);
# All three documents will be returned
SELECT * FROM articles
WHERE MATCH (title,body)
AGAINST ('"test proximity"@4' IN BOOLEAN MODE);
# Only two document will be returned.
SELECT * FROM articles
WHERE MATCH (title,body)
AGAINST ('"test proximity"@3' IN BOOLEAN MODE);
# Test with more word The last document will return, please notice there
# is no ordering requirement for proximity search.
SELECT * FROM articles
WHERE MATCH (title,body)
AGAINST ('"more test proximity"@4' IN BOOLEAN MODE);
SELECT * FROM articles
WHERE MATCH (title,body)
AGAINST ('"more test proximity"@3' IN BOOLEAN MODE);
# The phrase search will not require exact word ordering
SELECT * FROM articles
WHERE MATCH (title,body)
AGAINST ('"more test proximity"' IN BOOLEAN MODE);
}