Scan an index instead of a table for "SELECT count(*) FROM <tbl>" queries. Because an index is usually smaller than a table on disk, this saves some IO. (CVS 6315)

FossilOrigin-Name: 294ba6f743c9132dce0e73da480bd3c2071e7239
This commit is contained in:
danielk1977 2009-02-23 17:33:49 +00:00
parent 699b3d4f89
commit e2d7b24d08
9 changed files with 82 additions and 33 deletions

View File

@ -1,5 +1,5 @@
C Add\sthe\sreverse_unordered_selects\spragma.\s(CVS\s6314)
D 2009-02-23T16:52:08
C Scan\san\sindex\sinstead\sof\sa\stable\sfor\s"SELECT\scount(*)\sFROM\s<tbl>"\squeries.\sBecause\san\sindex\sis\susually\ssmaller\sthan\sa\stable\son\sdisk,\sthis\ssaves\ssome\sIO.\s(CVS\s6315)
D 2009-02-23T17:33:50
F Makefile.arm-wince-mingw32ce-gcc fcd5e9cd67fe88836360bb4f9ef4cb7f8e2fb5a0
F Makefile.in d64baddbf55cdf33ff030e14da837324711a4ef7
F Makefile.linux-gcc d53183f4aa6a9192d249731c90dbdffbd2c68654
@ -110,8 +110,8 @@ F src/build.c a1db48aec62c95049d783f231195812ff97ae268
F src/callback.c 5f10bca853e59a2c272bbfd5b720303f8b69e520
F src/complete.c cb14e06dbe79dee031031f0d9e686ff306afe07c
F src/date.c 0d804df3bbda46329946a01ff5c75c3f4f135218
F src/delete.c d9172e23f8b524ad23b24cc0dd7cbde8f2aecb54
F src/expr.c e22112c8db9b82748dd100c716b783cf5d9b6cc5
F src/delete.c 06e78b6eb53f27acc809a0f69178ea719748bb42
F src/expr.c 97545fa4058f86c67eb7cacadf60d2964300b00c
F src/fault.c dc88c821842157460750d2d61a8a8b4197d047ff
F src/func.c 2fb36cd7cc24e16845db203187d1e52811b0fa9c
F src/global.c 448419c44ce0701104c2121b0e06919b44514c0c
@ -152,13 +152,13 @@ F src/pragma.c 22ed04836aab8ce134c53be1ca896f3ad20fabdb
F src/prepare.c d0bbb4b1a8b9c1db6d13788929839bb63764680e
F src/printf.c 9866a9a9c4a90f6d4147407f373df3fd5d5f9b6f
F src/random.c 676b9d7ac820fe81e6fb2394ac8c10cff7f38628
F src/resolve.c b3aa625ec135d53a7e80c86c25ad56de46e0b415
F src/resolve.c 60a5f405540debee767d8c21ab78a5210b174fa2
F src/rowset.c ba9375f37053d422dd76965a9c370a13b6e1aac4
F src/select.c aa7328a23c0abe019f98bb7e1f4f63d62e20ba98
F src/shell.c f109ebbb50132926ebbc173a6c2d8838d5d78527
F src/sqlite.h.in 14f4d065bafed8500ea558a75a8e2be89c784d61
F src/sqlite3ext.h 1db7d63ab5de4b3e6b83dd03d1a4e64fef6d2a17
F src/sqliteInt.h c682534d78d7af014c81b30d2c9e75661f4ef990
F src/sqliteInt.h ac53d3b963c0c98b8f8c6df652a9cde2fd00e987
F src/sqliteLimit.h ffe93f5a0c4e7bd13e70cd7bf84cfb5c3465f45d
F src/status.c 237b193efae0cf6ac3f0817a208de6c6c6ef6d76
F src/table.c 332ab0ea691e63862e2a8bdfe2c0617ee61062a3
@ -195,7 +195,7 @@ F src/test_thread.c adb9175c466e1f487295b5b957603fc0a88ea293
F src/test_wsd.c c297d7d6b8a990239e1bd25935e81d612d8ae31d
F src/tokenize.c 6987fb7f0d6a87ac53499aee568cabb05eb4bea8
F src/trigger.c 9957e16e5445478f2cc60e26ac1bc836bb18d21a
F src/update.c fce4fa2945be1a9b65af2acec929669f7d1ac706
F src/update.c 9c11bc0bba520bcfce47e229a7235a9bc5f9121a
F src/utf.c 1da9c832dba0fa8f865b5b902d93f420a1ee4245
F src/util.c 1363f64351f3b544790f3c523439354c02f8c4e9
F src/vacuum.c 4929a585ef0fb1dfaf46302f8a9c4aa30c2d9cf5
@ -208,7 +208,7 @@ F src/vdbeblob.c 08d6bac666c1f6a5d67452f5fbf808cf1311d2c9
F src/vdbemem.c 543a79d722734d2f8b7ad70f08218c30bcc5bbf5
F src/vtab.c e39e011d7443a8d574b1b9cde207a35522e6df43
F src/walker.c 42bd3f00ca2ef5ae842304ec0d59903ef051412d
F src/where.c 72980baae14e7e71dc70c671b6cf34c4063dbd58
F src/where.c 591db2b9bc4d65b60ab28554eb40dc357358c47a
F test/aggerror.test a867e273ef9e3d7919f03ef4f0e8c0d2767944f2
F test/alias.test 597662c5d777a122f9a3df0047ea5c5bd383a911
F test/all.test 14165b3e32715b700b5f0cbf8f6e3833dda0be45
@ -673,7 +673,7 @@ F test/where6.test 42c4373595f4409d9c6a9987b4a60000ad664faf
F test/where7.test 2487cda68faabf5edeb524289913f00f8d64e223
F test/where8.test 1b9152a086408ee789166d0a954abc597372f868
F test/where8m.test c1010d61826412ff66abd29bfb32e5d6b37d965c
F test/where9.test a46d394037a40b56e7855d29cce951f91108c353
F test/where9.test 0e44fd96a838f7fa9ecd39a6569bfc4bd446faad
F test/whereA.test ef8d699d87934bd747119c75fbb4711b584a8b60
F test/wherelimit.test 5e9fd41e79bb2b2d588ed999d641d9c965619b31
F test/zeroblob.test 792124852ec61458a2eb527b5091791215e0be95
@ -701,7 +701,7 @@ F tool/speedtest16.c c8a9c793df96db7e4933f0852abb7a03d48f2e81
F tool/speedtest2.tcl ee2149167303ba8e95af97873c575c3e0fab58ff
F tool/speedtest8.c 2902c46588c40b55661e471d7a86e4dd71a18224
F tool/speedtest8inst1.c 293327bc76823f473684d589a8160bde1f52c14e
P 9b8acf8319ec760713773407a4d5a33dea8d75e8
R 41bbb1216086db2d528bb92c681c2add
U drh
Z 08cd8c8feaad5119cbc7d91cd8c2e6b1
P bc078e0007b6c3dc07722820bb53798b643212b3
R 19edfff27399a21c42d0d895b28d7f0b
U danielk1977
Z 309cb578835963c08d5f7f73ef6b305b

View File

@ -1 +1 @@
bc078e0007b6c3dc07722820bb53798b643212b3
294ba6f743c9132dce0e73da480bd3c2071e7239

View File

@ -12,7 +12,7 @@
** This file contains C code routines that are called by the parser
** in order to generate code for DELETE FROM statements.
**
** $Id: delete.c,v 1.193 2009/02/20 10:58:42 danielk1977 Exp $
** $Id: delete.c,v 1.194 2009/02/23 17:33:50 danielk1977 Exp $
*/
#include "sqliteInt.h"
@ -395,6 +395,7 @@ void sqlite3DeleteFrom(
/* Collect rowids of every row to be deleted.
*/
sqlite3VdbeAddOp2(v, OP_Null, 0, iRowSet);
pTabList->a[0].usesRowid = 1;
pWInfo = sqlite3WhereBegin(pParse, pTabList, pWhere, 0,
WHERE_FILL_ROWSET, iRowSet);
if( pWInfo==0 ) goto delete_from_cleanup;

View File

@ -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.414 2009/02/20 10:58:42 danielk1977 Exp $
** $Id: expr.c,v 1.415 2009/02/23 17:33:50 danielk1977 Exp $
*/
#include "sqliteInt.h"
@ -931,6 +931,7 @@ SrcList *sqlite3SrcListDup(sqlite3 *db, SrcList *p, int flags){
pNewItem->pOn = sqlite3ExprDup(db, pOldItem->pOn, flags);
pNewItem->pUsing = sqlite3IdListDup(db, pOldItem->pUsing);
pNewItem->colUsed = pOldItem->colUsed;
pNewItem->usesRowid = pOldItem->usesRowid;
}
return pNew;
}

View File

@ -14,7 +14,7 @@
** resolve all identifiers by associating them with a particular
** table and column.
**
** $Id: resolve.c,v 1.16 2009/02/19 14:39:25 danielk1977 Exp $
** $Id: resolve.c,v 1.17 2009/02/23 17:33:50 danielk1977 Exp $
*/
#include "sqliteInt.h"
#include <stdlib.h>
@ -347,14 +347,18 @@ static int lookupName(
** column number is greater than the number of bits in the bitmask
** then set the high-order bit of the bitmask.
*/
if( pExpr->iColumn>=0 && pMatch!=0 ){
int n = pExpr->iColumn;
testcase( n==BMS-1 );
if( n>=BMS ){
n = BMS-1;
if( pMatch ){
if( pExpr->iColumn>=0 ){
int n = pExpr->iColumn;
testcase( n==BMS-1 );
if( n>=BMS ){
n = BMS-1;
}
assert( pMatch->iCursor==pExpr->iTable );
pMatch->colUsed |= ((Bitmask)1)<<n;
}else{
pMatch->usesRowid = 1;
}
assert( pMatch->iCursor==pExpr->iTable );
pMatch->colUsed |= ((Bitmask)1)<<n;
}
lookupname_end:

View File

@ -11,7 +11,7 @@
*************************************************************************
** Internal interface definitions for SQLite.
**
** @(#) $Id: sqliteInt.h,v 1.835 2009/02/23 16:52:08 drh Exp $
** @(#) $Id: sqliteInt.h,v 1.836 2009/02/23 17:33:50 danielk1977 Exp $
*/
#ifndef _SQLITEINT_H_
#define _SQLITEINT_H_
@ -1601,6 +1601,7 @@ struct SrcList {
u8 isPopulated; /* Temporary table associated with SELECT is populated */
u8 jointype; /* Type of join between this able and the previous */
u8 notIndexed; /* True if there is a NOT INDEXED clause */
u8 usesRowid; /* True if the rowid field is read */
int iCursor; /* The VDBE cursor number used to access this table */
Expr *pOn; /* The ON clause of a join */
IdList *pUsing; /* The USING clause of a join */

View File

@ -12,7 +12,7 @@
** This file contains C code routines that are called by the parser
** to handle UPDATE statements.
**
** $Id: update.c,v 1.193 2009/02/20 10:58:42 danielk1977 Exp $
** $Id: update.c,v 1.194 2009/02/23 17:33:50 danielk1977 Exp $
*/
#include "sqliteInt.h"
@ -343,6 +343,7 @@ void sqlite3Update(
/* Begin the database scan
*/
sqlite3VdbeAddOp2(v, OP_Null, 0, regOldRowid);
pTabList->a[0].usesRowid = 1;
pWInfo = sqlite3WhereBegin(pParse, pTabList, pWhere, 0,
WHERE_ONEPASS_DESIRED, 0);
if( pWInfo==0 ) goto update_cleanup;

View File

@ -16,7 +16,7 @@
** so is applicable. Because this module is responsible for selecting
** indices, you might also think of this module as the "query optimizer".
**
** $Id: where.c,v 1.371 2009/02/23 16:52:08 drh Exp $
** $Id: where.c,v 1.372 2009/02/23 17:33:50 danielk1977 Exp $
*/
#include "sqliteInt.h"
@ -1715,15 +1715,15 @@ static double bestVirtualIndex(
** * Whether or not there must be separate lookups in the
** index and in the main table.
**
** If there was an INDEXED BY clause attached to the table in the SELECT
** statement, then this function only considers plans using the
** If there was an INDEXED BY clause (pSrc->pIndex) attached to the table in
** the SQL statement, then this function only considers plans using the
** named index. If one cannot be found, then the returned cost is
** SQLITE_BIG_DBL. If a plan can be found that uses the named index,
** then the cost is calculated in the usual way.
**
** If a NOT INDEXED clause was attached to the table in the SELECT
** statement, then no indexes are considered. However, the selected
** plan may still take advantage of the tables built-in rowid
** If a NOT INDEXED clause (pSrc->notIndexed!=0) was attached to the table
** in the SELECT statement, then no indexes are considered. However, the
** selected plan may still take advantage of the tables built-in rowid
** index.
*/
static void bestIndex(
@ -2035,6 +2035,21 @@ static void bestIndex(
}
}
if( pCost->plan.wsFlags==0 && pSrc->colUsed==0 && pSrc->usesRowid==0 ){
Index *pSmallest = 0;
assert( pSrc->pIndex==0 );
for(pProbe=pSrc->pTab->pIndex; pProbe; pProbe=pProbe->pNext){
if( !pSmallest || pProbe->nColumn<pSmallest->nColumn ){
pSmallest = pProbe;
}
}
if( pSmallest && pSmallest->nColumn<pSrc->pTab->nCol ){
assert( pCost->plan.nEq==0 );
pCost->plan.u.pIdx = pSmallest;
pCost->plan.wsFlags = WHERE_COLUMN_RANGE|WHERE_IDX_ONLY;
}
}
/* Report the best result
*/
pCost->plan.wsFlags |= eqTermMask;

View File

@ -11,7 +11,7 @@
# This file implements regression tests for SQLite library. The
# focus of this file is testing the multi-index OR clause optimizer.
#
# $Id: where9.test,v 1.5 2009/01/08 21:00:03 drh Exp $
# $Id: where9.test,v 1.6 2009/02/23 17:33:50 danielk1977 Exp $
set testdir [file dirname $argv0]
source $testdir/tester.tcl
@ -802,4 +802,30 @@ do_test where9-6.8.2 {
}
} {1 {cannot use index: t1b}}
do_test where9-7.1 {
execsql {
CREATE TABLE t5(a, b, c);
EXPLAIN QUERY PLAN SELECT count(*) FROM t5;
}
} {0 0 {TABLE t5}}
do_test where9-7.2 {
execsql {
CREATE INDEX t5i1 ON t5(a, b);
EXPLAIN QUERY PLAN SELECT count(*) FROM t5;
}
} {0 0 {TABLE t5 WITH INDEX t5i1}}
do_test where9-7.3 {
execsql {
CREATE INDEX t5i2 ON t5(b);
EXPLAIN QUERY PLAN SELECT count(*) FROM t5;
}
} {0 0 {TABLE t5 WITH INDEX t5i2}}
do_test where9-7.4 {
execsql {
CREATE TABLE t6(a, b, c);
CREATE INDEX t6i1 ON t6(a, b, c);
EXPLAIN QUERY PLAN SELECT count(*) FROM t6;
}
} {0 0 {TABLE t6}}
finish_test