From 042f88e5b4561b16eaede2b17c8ad869fde6f9db Mon Sep 17 00:00:00 2001 From: dan Date: Mon, 31 Oct 2011 11:36:29 +0000 Subject: [PATCH] Add new file ext/fts3/README.content, describing the experimental FTS4 content option. FossilOrigin-Name: 13a9d085e1a5654a97b8d26bae7182ca6c0c237b --- ext/fts3/README.content | 178 ++++++++++++++++++++++++++++++++++++++++ manifest | 13 +-- manifest.uuid | 2 +- test/fts4content.test | 23 ++++++ 4 files changed, 209 insertions(+), 7 deletions(-) create mode 100644 ext/fts3/README.content diff --git a/ext/fts3/README.content b/ext/fts3/README.content new file mode 100644 index 0000000000..ab986754df --- /dev/null +++ b/ext/fts3/README.content @@ -0,0 +1,178 @@ + +FTS4 CONTENT OPTION + + Normally, in order to create a full-text index on a dataset, the FTS4 + module stores a copy of all indexed documents in a specially created + database table. + + As of SQLite version 3.7.9, FTS4 supports a new option - "content" - + designed to extend FTS4 to support the creation of full-text indexes where: + + * The indexed documents are not stored within the SQLite database + at all (a "contentless" FTS4 table), or + + * The indexed documents are stored in a database table created and + managed by the user (an "external content" FTS4 table). + + Because the indexed documents themselves are usually much larger than + the full-text index, the content option can sometimes be used to achieve + significant space savings. + +CONTENTLESS FTS4 TABLES + + In order to create an FTS4 table that does not store a copy of the indexed + documents at all, the content option should be set to an empty string. + For example, the following SQL creates such an FTS4 table with three + columns - "a", "b", and "c": + + CREATE VIRTUAL TABLE t1 USING fts4(content="", a, b, c); + + Data can be inserted into such an FTS4 table using an INSERT statements. + However, unlike ordinary FTS4 tables, the user must supply an explicit + integer docid value. For example: + + -- This statement is Ok: + INSERT INTO t1(docid, a, b, c) VALUES(1, 'a b c', 'd e f', 'g h i'); + + -- This statement causes an error, as no docid value has been provided: + INSERT INTO t1(a, b, c) VALUES('j k l', 'm n o', 'p q r'); + + It is not possible to UPDATE or DELETE a row stored in a contentless FTS4 + table. Attempting to do so is an error. + + Contentless FTS4 tables also support SELECT statements. However, it is + an error to attempt to retrieve the value of any table column other than + the docid column. The auxiliary function matchinfo() may be used, but + snippet() and offsets() may not. For example: + + -- The following statements are Ok: + SELECT docid FROM t1 WHERE t1 MATCH 'xxx'; + SELECT docid FROM t1 WHERE a MATCH 'xxx'; + SELECT matchinfo(t1) FROM t1 WHERE t1 MATCH 'xxx'; + + -- The following statements all cause errors, as the value of columns + -- other than docid are required to evaluate them. + SELECT * FROM t1; + SELECT a, b FROM t1 WHERE t1 MATCH 'xxx'; + SELECT docid FROM t1 WHERE a LIKE 'xxx%'; + SELECT snippet(t1) FROM t1 WHERE t1 MATCH 'xxx'; + + Errors related to attempting to retrieve column values other than docid + are runtime errors that occur within sqlite3_step(). In some cases, for + example if the MATCH expression in a SELECT query matches zero rows, there + may be no error at all even if a statement does refer to column values + other than docid. + +EXTERNAL CONTENT FTS4 TABLES + + An "external content" FTS4 table is similar to a contentless table, except + that if evaluation of a query requires the value of a column other than + docid, FTS4 attempts to retrieve that value from a table (or view, or + virtual table) nominated by the user (hereafter referred to as the "content + table"). The FTS4 module never writes to the content table, and writing + to the content table does not affect the full-text index. It is the + responsibility of the user to ensure that the content table and the + full-text index are consistent. + + An external content FTS4 table is created by setting the content option + to the name of a table (or view, or virtual table) that may be queried by + FTS4 to retrieve column values when required. If the nominated table does + not exist, then an external content table behaves in the same way as + a contentless table. For example: + + CREATE TABLE t2(id INTEGER PRIMARY KEY, a, b, c); + CREATE VIRTUAL TABLE t3 USING fts4(content="t2", a, c); + + Assuming the nominated table does exist, then its columns must be the same + as or a superset of those defined for the FTS table. + + When a users query on the FTS table requires a column value other than + docid, FTS attempts to read this value from the corresponding column of + the row in the content table with a rowid value equal to the current FTS + docid. Or, if such a row cannot be found in the content table, a NULL + value is used instead. For example: + + CREATE TABLE t2(id INTEGER PRIMARY KEY, a, b, c, d); + CREATE VIRTUAL TABLE t3 USING fts4(content="t2", b, c); + + INSERT INTO t2 VALUES(2, 'a b', 'c d', 'e f'); + INSERT INTO t2 VALUES(3, 'g h', 'i j', 'k l'); + INSERT INTO t3(docid, b, c) SELECT id, b, c FROM t2; + + -- The following query returns a single row with two columns containing + -- the text values "i j" and "k l". + -- + -- The query uses the full-text index to discover that the MATCH + -- term matches the row with docid=3. It then retrieves the values + -- of columns b and c from the row with rowid=3 in the content table + -- to return. + -- + SELECT * FROM t3 WHERE t3 MATCH 'k'; + + -- Following the UPDATE, the query still returns a single row, this + -- time containing the text values "xxx" and "yyy". This is because the + -- full-text index still indicates that the row with docid=3 matches + -- the FTS4 query 'k', even though the documents stored in the content + -- table have been modified. + -- + UPDATE t2 SET b = 'xxx', c = 'yyy' WHERE rowid = 3; + SELECT * FROM t3 WHERE t3 MATCH 'k'; + + -- Following the DELETE below, the query returns one row containing two + -- NULL values. NULL values are returned because FTS is unable to find + -- a row with rowid=3 within the content table. + -- + DELETE FROM t2; + SELECT * FROM t3 WHERE t3 MATCH 'k'; + + When a row is deleted from an external content FTS4 table, FTS4 needs to + retrieve the column values of the row being deleted from the content table. + This is so that FTS4 can update the full-text index entries for each token + that occurs within the deleted row to indicate that that row has been + deleted. If the content table row cannot be found, or if it contains values + inconsistent with the contents of the FTS index, the results can be difficult + to predict. The FTS index may be left containing entries corresponding to the + deleted row, which can lead to seemingly nonsensical results being returned + by subsequent SELECT queries. The same applies when a row is updated, as + internally an UPDATE is the same as a DELETE followed by an INSERT. + + Instead of writing separately to the full-text index and the content table, + some users may wish to use database triggers to keep the full-text index + up to date with respect to the set of documents stored in the content table. + For example, using the tables from earlier examples: + + CREATE TRIGGER t2_bu BEFORE UPDATE ON t2 BEGIN + DELETE FROM t3 WHERE docid=old.rowid; + END; + CREATE TRIGGER t2_bd BEFORE DELETE ON t2 BEGIN + DELETE FROM t3 WHERE docid=old.rowid; + END; + + CREATE TRIGGER t2_bu AFTER UPDATE ON t2 BEGIN + INSERT INTO t3(docid, b, c) VALUES(new.rowid, new.b, new.c); + END; + CREATE TRIGGER t2_bd AFTER INSERT ON t2 BEGIN + INSERT INTO t3(docid, b, c) VALUES(new.rowid, new.b, new.c); + END; + + The DELETE trigger must be fired before the actual delete takes place + on the content table. This is so that FTS4 can still retrieve the original + values in order to update the full-text index. And the INSERT trigger must + be fired after the new row is inserted, so as to handle the case where the + rowid is assigned automatically within the system. The UPDATE trigger must + be split into two parts, one fired before and one after the update of the + content table, for the same reasons. + + FTS4 features a special command similar to the 'optimize' command that + deletes the entire full-text index and rebuilds it based on the current + set of documents in the content table. Assuming again that "t3" is the + name of the external content FTS4 table, the command is: + + INSERT INTO t3(t3) VALUES('rebuild'); + + This command may also be used with ordinary FTS4 tables, although it may + only be useful if the full-text index has somehow become corrupt. It is an + error to attempt to rebuild the full-text index maintained by a contentless + FTS4 table. + + diff --git a/manifest b/manifest index 85be364945..3dc448a706 100644 --- a/manifest +++ b/manifest @@ -1,5 +1,5 @@ -C Update\sfts3fault.test\sto\saccount\sfor\sthe\ssqlite3_errmsg()\srelated\schanges\sin\s[8f88cc4e61]\sand\s[dcb7879347]. -D 2011-10-31T06:52:51.929 +C Add\snew\sfile\sext/fts3/README.content,\sdescribing\sthe\sexperimental\sFTS4\scontent\soption. +D 2011-10-31T11:36:29.263 F Makefile.arm-wince-mingw32ce-gcc d6df77f1f48d690bd73162294bbba7f59507c72f F Makefile.in a162fe39e249b8ed4a65ee947c30152786cfe897 F Makefile.linux-gcc 91d710bdc4998cb015f39edf3cb314ec4f4d7e23 @@ -59,6 +59,7 @@ F ext/fts2/fts2_tokenizer.c 26e993a00b2bd5b6e73c155597361710b12ffe25 F ext/fts2/fts2_tokenizer.h a7e46462d935a314b2682287f12f27530a3ee08e F ext/fts2/fts2_tokenizer1.c 0123d21078e053bd98fd6186c5c6dc6d67969f2e F ext/fts2/mkfts2amal.tcl 974d5d438cb3f7c4a652639262f82418c1e4cff0 +F ext/fts3/README.content fdc666a70d5257a64fee209f97cf89e0e6e32b51 F ext/fts3/README.syntax a19711dc5458c20734b8e485e75fb1981ec2427a F ext/fts3/README.tokenizers 998756696647400de63d5ba60e9655036cb966e9 F ext/fts3/README.txt 8c18f41574404623b76917b9da66fcb0ab38328d @@ -490,7 +491,7 @@ F test/fts3shared.test 8bb266521d7c5495c0ae522bb4d376ad5387d4a2 F test/fts3snippet.test 8e956051221a34c7daeb504f023cb54d5fa5a8b2 F test/fts3sort.test 95be0b19d7e41c44b29014f13ea8bddd495fd659 F test/fts4aa.test 6e7f90420b837b2c685f3bcbe84c868492d40a68 -F test/fts4content.test c5f531ecfc3d446b90032cae212549dbbb18dd78 +F test/fts4content.test 2624253c7e5a32d0c0d51f776dcd4526f0a51097 F test/func.test 6c5ce11e3a0021ca3c0649234e2d4454c89110ca F test/func2.test 772d66227e4e6684b86053302e2d74a2500e1e0f F test/func3.test 001021e5b88bd02a3b365a5c5fd8f6f49d39744a @@ -973,7 +974,7 @@ F tool/tostr.awk e75472c2f98dd76e06b8c9c1367f4ab07e122d06 F tool/vdbe-compress.tcl d70ea6d8a19e3571d7ab8c9b75cba86d1173ff0f F tool/warnings-clang.sh 9f406d66e750e8ac031c63a9ef3248aaa347ef2a F tool/warnings.sh fbc018d67fd7395f440c28f33ef0f94420226381 -P 5b82ec6fbbd2f4195ad06dd911de3817373ad5bf -R 29c8753d0115fb58d01891e5cb413fc9 +P 3f2d49c6786beb6ff9d56376364ebc6cd9136346 +R 6381e06f1c55fb7700be42aa3a0138e3 U dan -Z 39aba6063ce752fd13bbccdce4880df4 +Z ff269487aa8ff3e3aac698089b9c29e4 diff --git a/manifest.uuid b/manifest.uuid index 92f2a1e0e7..2fe8d0f4b6 100644 --- a/manifest.uuid +++ b/manifest.uuid @@ -1 +1 @@ -3f2d49c6786beb6ff9d56376364ebc6cd9136346 \ No newline at end of file +13a9d085e1a5654a97b8d26bae7182ca6c0c237b \ No newline at end of file diff --git a/test/fts4content.test b/test/fts4content.test index 8295d91d61..025b600b6b 100644 --- a/test/fts4content.test +++ b/test/fts4content.test @@ -38,6 +38,10 @@ ifcapable !fts3 { # # 6.* - Test the effects of messing with the schema of table xxx after # creating a content=xxx FTS index. +# +# 7.* - Test that if content=xxx is specified and table xxx does not +# exist, the FTS table can still be used for INSERT and some +# SELECT statements. # do_execsql_test 1.1.1 { @@ -475,4 +479,23 @@ do_execsql_test 7.1.2 { SELECT docid FROM ft8 WHERE ft8 MATCH 'N'; } {13 15} +do_execsql_test 7.2.1 { + CREATE VIRTUAL TABLE ft9 USING fts4(content=, x); + INSERT INTO ft9(docid, x) VALUES(13, 'U O N X G'); + INSERT INTO ft9(docid, x) VALUES(14, 'C J J U B'); + INSERT INTO ft9(docid, x) VALUES(15, 'N J Y G X'); + INSERT INTO ft9(docid, x) VALUES(16, 'R Y D O R'); + INSERT INTO ft9(docid, x) VALUES(17, 'I Y T Q O'); +} +do_execsql_test 7.2.2 { + SELECT docid FROM ft9 WHERE ft9 MATCH 'N'; +} {13 15} +do_execsql_test 7.2.3 { + SELECT name FROM sqlite_master WHERE name LIKE 'ft9_%'; +} {ft9_segments ft9_segdir ft9_docsize ft9_stat} + +do_catchsql_test 7.2.4 { + SELECT * FROM ft9 WHERE ft9 MATCH 'N'; +} {1 {SQL logic error or missing database}} + finish_test