From: danielk1977 Date: Thu, 2 Oct 2008 13:50:55 +0000 (+0000) Subject: Optimize queries that contain "WHERE rowid IN (x, y, z...)" by using an intkey btree... X-Git-Tag: version-3.6.10~417 X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=41a05b7beea50d0d619f09afa5576e3491648463;p=thirdparty%2Fsqlite.git Optimize queries that contain "WHERE rowid IN (x, y, z...)" by using an intkey btree to store the (x, y, z...) set instead of an index btree. (CVS 5760) FossilOrigin-Name: 803a1736d56b3c07b8ad38715fe0e39196ecc507 --- diff --git a/manifest b/manifest index a09f22df23..8c5d7d637c 100644 --- a/manifest +++ b/manifest @@ -1,5 +1,5 @@ -C Adjust\sthe\smemory\susage\sbounds\son\sthe\smemsubsys1.test\sscript\sso\sthat\nit\sworks\son\samd64.\s(CVS\s5759) -D 2008-10-01T13:55:51 +C Optimize\squeries\sthat\scontain\s"WHERE\srowid\sIN\s(x,\sy,\sz...)"\sby\susing\san\sintkey\sbtree\sto\sstore\sthe\s(x,\sy,\sz...)\sset\sinstead\sof\san\sindex\sbtree.\s(CVS\s5760) +D 2008-10-02T13:50:56 F Makefile.arm-wince-mingw32ce-gcc fcd5e9cd67fe88836360bb4f9ef4cb7f8e2fb5a0 F Makefile.in e4ab842f9a64ef61d57093539a8aab76b12810db F Makefile.linux-gcc d53183f4aa6a9192d249731c90dbdffbd2c68654 @@ -107,7 +107,7 @@ F src/callback.c 7a40fd44da3eb89e7f6eff30aa6f940c45d73a97 F src/complete.c cb14e06dbe79dee031031f0d9e686ff306afe07c F src/date.c 5c092296c03d658e84884121a694150964d6861d F src/delete.c bae6684aa02e1f7cf6328023157c91d9cf94200b -F src/expr.c 04822d5c7af85fd195a5f72501ab5e8d99768fae +F src/expr.c 61f5afca422f34194225cfd9bca9f2efd96c6179 F src/fault.c dc88c821842157460750d2d61a8a8b4197d047ff F src/func.c 8431b40a7843d1024145684d303c55b4ee087bbe F src/global.c 20a3fe46c8287a01ba3a7442558f0eb70c66b19a @@ -151,7 +151,7 @@ F src/select.c f118f8db2ce91a4cf972e6ae88c8e7cc8543f513 F src/shell.c d83b578a8ccdd3e0e7fef4388a0887ce9f810967 F src/sqlite.h.in 2be75cc1f2a5515db910e8d0e2d5954b493fd1f3 F src/sqlite3ext.h 1e3887c9bd3ae66cb599e922824b04cd0d0f2c3e -F src/sqliteInt.h dbe2797806c48f4a90adfea69dfbea95edd722ae +F src/sqliteInt.h 437b408a7473293a903eb63f3c1d6ca814a13cdb F src/sqliteLimit.h f435e728c6b620ef7312814d660a81f9356eb5c8 F src/status.c 237b193efae0cf6ac3f0817a208de6c6c6ef6d76 F src/table.c 22744786199c9195720c15a7a42cb97b2e2728d8 @@ -362,6 +362,7 @@ F test/icu.test f51d0f4407ff8bb1e872f51a0e8b08fdc5a6897e F test/in.test d49419c6df515852f477fa513f3317181d46bc92 F test/in2.test 5d4c61d17493c832f7d2d32bef785119e87bde75 F test/in3.test 3cbf58c87f4052cee3a58b37b6389777505aa0c0 +F test/in4.test c043f75147295e9f6ad5040a5cda2c485736c2c8 F test/incrblob.test e50cf41ac64e76ca4f8881ecb8d28fd988503ad5 F test/incrblob2.test c82a780356bdf4d0c77f1adf0ea888248904fc07 F test/incrblob_err.test c577c91d4ed9e8336cdb188b15d6ee2a6fe9604e @@ -637,7 +638,7 @@ F tool/speedtest16.c c8a9c793df96db7e4933f0852abb7a03d48f2e81 F tool/speedtest2.tcl ee2149167303ba8e95af97873c575c3e0fab58ff F tool/speedtest8.c 1dbced29de5f59ba2ebf877edcadf171540374d1 F tool/speedtest8inst1.c 293327bc76823f473684d589a8160bde1f52c14e -P 59d2e89e2181c26b18eac68ccc80ea3018f70a5e -R 2287b309c0341dad7ec54713b965b29d -U drh -Z d9d819f707dc5f486bedf318813a096b +P aabde23fe19bd95371fdebdde66ac553dfd53f8e +R 280f60e55a9bc8f499b588b678dbf711 +U danielk1977 +Z 0496772435641c7d88e45dbde24176e8 diff --git a/manifest.uuid b/manifest.uuid index 0f29031168..7d1220adcb 100644 --- a/manifest.uuid +++ b/manifest.uuid @@ -1 +1 @@ -aabde23fe19bd95371fdebdde66ac553dfd53f8e \ No newline at end of file +803a1736d56b3c07b8ad38715fe0e39196ecc507 \ No newline at end of file diff --git a/src/expr.c b/src/expr.c index ab0cf1e318..1925034dcf 100644 --- a/src/expr.c +++ b/src/expr.c @@ -12,7 +12,7 @@ ** This file contains routines used for analyzing expressions and ** for generating VDBE code that evaluates expressions in SQLite. ** -** $Id: expr.c,v 1.394 2008/09/17 00:13:12 drh Exp $ +** $Id: expr.c,v 1.395 2008/10/02 13:50:56 danielk1977 Exp $ */ #include "sqliteInt.h" #include @@ -1214,11 +1214,13 @@ int sqlite3FindInIndex(Parse *pParse, Expr *pX, int *prNotFound){ if( eType==0 ){ int rMayHaveNull = 0; + eType = IN_INDEX_EPH; if( prNotFound ){ *prNotFound = rMayHaveNull = ++pParse->nMem; + }else if( pX->pLeft->iColumn<0 && pX->pSelect==0 ){ + eType = IN_INDEX_ROWID; } - sqlite3CodeSubselect(pParse, pX, rMayHaveNull); - eType = IN_INDEX_EPH; + sqlite3CodeSubselect(pParse, pX, rMayHaveNull, eType==IN_INDEX_ROWID); }else{ pX->iTable = iTab; } @@ -1237,9 +1239,20 @@ int sqlite3FindInIndex(Parse *pParse, Expr *pX, int *prNotFound){ ** ** The pExpr parameter describes the expression that contains the IN ** operator or subquery. +** +** If parameter isRowid is non-zero, then expression pExpr is guaranteed +** to be of the form " IN (?, ?, ?)", where is a reference +** to some integer key column of a table B-Tree. In this case, use an +** intkey B-Tree to store the set of IN(...) values instead of the usual +** (slower) variable length keys B-Tree. */ #ifndef SQLITE_OMIT_SUBQUERY -void sqlite3CodeSubselect(Parse *pParse, Expr *pExpr, int rMayHaveNull){ +void sqlite3CodeSubselect( + Parse *pParse, + Expr *pExpr, + int rMayHaveNull, + int isRowid +){ int testAddr = 0; /* One-time test address */ Vdbe *v = sqlite3GetVdbe(pParse); if( v==0 ) return; @@ -1267,12 +1280,13 @@ void sqlite3CodeSubselect(Parse *pParse, Expr *pExpr, int rMayHaveNull){ char affinity; KeyInfo keyInfo; int addr; /* Address of OP_OpenEphemeral instruction */ + Expr *pLeft = pExpr->pLeft; if( rMayHaveNull ){ sqlite3VdbeAddOp2(v, OP_Null, 0, rMayHaveNull); } - affinity = sqlite3ExprAffinity(pExpr->pLeft); + affinity = sqlite3ExprAffinity(pLeft); /* Whether this is an 'x IN(SELECT...)' or an 'x IN()' ** expression it is handled the same way. A virtual table is @@ -1288,7 +1302,7 @@ void sqlite3CodeSubselect(Parse *pParse, Expr *pExpr, int rMayHaveNull){ ** is used. */ pExpr->iTable = pParse->nTab++; - addr = sqlite3VdbeAddOp2(v, OP_OpenEphemeral, pExpr->iTable, 1); + addr = sqlite3VdbeAddOp2(v, OP_OpenEphemeral, pExpr->iTable, !isRowid); memset(&keyInfo, 0, sizeof(keyInfo)); keyInfo.nField = 1; @@ -1301,6 +1315,7 @@ void sqlite3CodeSubselect(Parse *pParse, Expr *pExpr, int rMayHaveNull){ SelectDest dest; ExprList *pEList; + assert( !isRowid ); sqlite3SelectDestInit(&dest, SRT_Set, pExpr->iTable); dest.affinity = (int)affinity; assert( (pExpr->iTable&0x0000FFFF)==pExpr->iTable ); @@ -1351,14 +1366,23 @@ void sqlite3CodeSubselect(Parse *pParse, Expr *pExpr, int rMayHaveNull){ r3 = sqlite3ExprCodeTarget(pParse, pE2, r1); assert( pParse->disableColCache>0 ); pParse->disableColCache--; - sqlite3VdbeAddOp4(v, OP_MakeRecord, r3, 1, r2, &affinity, 1); - sqlite3ExprCacheAffinityChange(pParse, r3, 1); - sqlite3VdbeAddOp2(v, OP_IdxInsert, pExpr->iTable, r2); + + if( isRowid ){ + sqlite3VdbeAddOp2(v, OP_Null, 0, r2); + sqlite3VdbeAddOp2(v, OP_MustBeInt, r3, sqlite3VdbeCurrentAddr(v)+2); + sqlite3VdbeAddOp3(v, OP_Insert, pExpr->iTable, r2, r3); + }else{ + sqlite3VdbeAddOp4(v, OP_MakeRecord, r3, 1, r2, &affinity, 1); + sqlite3ExprCacheAffinityChange(pParse, r3, 1); + sqlite3VdbeAddOp2(v, OP_IdxInsert, pExpr->iTable, r2); + } } sqlite3ReleaseTempReg(pParse, r1); sqlite3ReleaseTempReg(pParse, r2); } - sqlite3VdbeChangeP4(v, addr, (void *)&keyInfo, P4_KEYINFO); + if( !isRowid ){ + sqlite3VdbeChangeP4(v, addr, (void *)&keyInfo, P4_KEYINFO); + } break; } @@ -2026,7 +2050,7 @@ int sqlite3ExprCodeTarget(Parse *pParse, Expr *pExpr, int target){ testcase( op==TK_EXISTS ); testcase( op==TK_SELECT ); if( pExpr->iColumn==0 ){ - sqlite3CodeSubselect(pParse, pExpr, 0); + sqlite3CodeSubselect(pParse, pExpr, 0, 0); } inReg = pExpr->iColumn; break; @@ -2109,7 +2133,7 @@ int sqlite3ExprCodeTarget(Parse *pParse, Expr *pExpr, int target){ sqlite3VdbeJumpHere(v, j3); /* Copy the value of register rNotFound (which is either NULL or 0) - ** into the target register. This will be the result of the + ** into the target register. This will be the result of the ** expression. */ sqlite3VdbeAddOp2(v, OP_Copy, rNotFound, target); diff --git a/src/sqliteInt.h b/src/sqliteInt.h index af12e0f866..daa85a7224 100644 --- a/src/sqliteInt.h +++ b/src/sqliteInt.h @@ -11,7 +11,7 @@ ************************************************************************* ** Internal interface definitions for SQLite. ** -** @(#) $Id: sqliteInt.h,v 1.772 2008/09/12 16:03:48 drh Exp $ +** @(#) $Id: sqliteInt.h,v 1.773 2008/10/02 13:50:56 danielk1977 Exp $ */ #ifndef _SQLITEINT_H_ #define _SQLITEINT_H_ @@ -2367,7 +2367,7 @@ void sqlite3AlterRenameTable(Parse*, SrcList*, Token*); int sqlite3GetToken(const unsigned char *, int *); void sqlite3NestedParse(Parse*, const char*, ...); void sqlite3ExpirePreparedStatements(sqlite3*); -void sqlite3CodeSubselect(Parse *, Expr *, int); +void sqlite3CodeSubselect(Parse *, Expr *, int, int); void sqlite3SelectPrep(Parse*, Select*, NameContext*); int sqlite3ResolveExprNames(NameContext*, Expr*); void sqlite3ResolveSelectNames(Parse*, Select*, NameContext*); diff --git a/test/in4.test b/test/in4.test new file mode 100644 index 0000000000..c13d8b1674 --- /dev/null +++ b/test/in4.test @@ -0,0 +1,93 @@ +# 2008 September 1 +# +# The author disclaims copyright to this source code. In place of +# a legal notice, here is a blessing: +# +# May you do good and not evil. +# May you find forgiveness for yourself and forgive others. +# May you share freely, never taking more than you give. +# +#*********************************************************************** +# +# $Id: in4.test,v 1.1 2008/10/02 13:50:56 danielk1977 Exp $ + +set testdir [file dirname $argv0] +source $testdir/tester.tcl + +do_test in4-1.1 { + execsql { + CREATE TABLE t1(a, b); + CREATE INDEX i1 ON t1(a); + } +} {} +do_test in4-1.2 { + execsql { + SELECT * FROM t1 WHERE a IN ('aaa', 'bbb', 'ccc'); + } +} {} +do_test in4-1.3 { + execsql { + INSERT INTO t1 VALUES('aaa', 1); + INSERT INTO t1 VALUES('ddd', 2); + INSERT INTO t1 VALUES('ccc', 3); + INSERT INTO t1 VALUES('eee', 4); + SELECT b FROM t1 WHERE a IN ('aaa', 'bbb', 'ccc'); + } +} {1 3} +do_test in4-1.4 { + execsql { + SELECT a FROM t1 WHERE rowid IN (1, 3); + } +} {aaa ccc} +do_test in4-1.5 { + execsql { + SELECT a FROM t1 WHERE rowid IN (); + } +} {} +do_test in4-1.6 { + execsql { + SELECT a FROM t1 WHERE a IN ('ddd'); + } +} {ddd} + +do_test in4-2.1 { + execsql { + CREATE TABLE t2(a INTEGER PRIMARY KEY, b TEXT); + INSERT INTO t2 VALUES(-1, '-one'); + INSERT INTO t2 VALUES(0, 'zero'); + INSERT INTO t2 VALUES(1, 'one'); + INSERT INTO t2 VALUES(2, 'two'); + INSERT INTO t2 VALUES(3, 'three'); + } +} {} + +do_test in4-2.2 { + execsql { SELECT b FROM t2 WHERE a IN (0, 2) } +} {zero two} + +do_test in4-2.3 { + execsql { SELECT b FROM t2 WHERE a IN (2, 0) } +} {zero two} + +do_test in4-2.4 { + execsql { SELECT b FROM t2 WHERE a IN (2, -1) } +} {-one two} + +do_test in4-2.5 { + execsql { SELECT b FROM t2 WHERE a IN (NULL, 3) } +} {three} + +do_test in4-2.6 { + execsql { SELECT b FROM t2 WHERE a IN (1.0, 2.1) } +} {one} + +do_test in4-2.7 { + execsql { SELECT b FROM t2 WHERE a IN ('1', '2') } +} {one two} + +do_test in4-2.8 { + execsql { SELECT b FROM t2 WHERE a IN ('', '0.0.0', '2') } +} {two} + +finish_test +