Fix for ticket [b2fa5424e6fcb15]: Better define the format of the sqlite_stat4

file for WITHOUT ROWID tables and make sure the ANALYZE command generates a
file in the appropriate format.  Use the sqlite_stat4 data to enable the use
of WHERE terms that cover all indexed columns plus some prefix of columns
in the primary key.

FossilOrigin-Name: bc2de8095fa9c385db0adf22ca55b0298a33c284
This commit is contained in:
drh 2014-06-30 18:57:53 +00:00
commit c7de8267a8
6 changed files with 194 additions and 46 deletions

View File

@ -1,5 +1,5 @@
C Add\smakefile\stargets\sfor\svarious\sdiagnostic\stools,\ssuch\sas\sshowstat4.\nFix\sharmless\scompiler\swarnings\sin\sdiagnostic\stools.
D 2014-06-30T11:14:26.241
C Fix\sfor\sticket\s[b2fa5424e6fcb15]:\sBetter\sdefine\sthe\sformat\sof\sthe\ssqlite_stat4\nfile\sfor\sWITHOUT\sROWID\stables\sand\smake\ssure\sthe\sANALYZE\scommand\sgenerates\sa\nfile\sin\sthe\sappropriate\sformat.\s\sUse\sthe\ssqlite_stat4\sdata\sto\senable\sthe\suse\nof\sWHERE\sterms\sthat\scover\sall\sindexed\scolumns\splus\ssome\sprefix\sof\scolumns\nin\sthe\sprimary\skey.
D 2014-06-30T18:57:53.330
F Makefile.arm-wince-mingw32ce-gcc d6df77f1f48d690bd73162294bbba7f59507c72f
F Makefile.in 1732320ecac3fee229d560d7ef2afa34681d1815
F Makefile.linux-gcc 91d710bdc4998cb015f39edf3cb314ec4f4d7e23
@ -161,7 +161,7 @@ F sqlite.pc.in 42b7bf0d02e08b9e77734a47798d1a55a9e0716b
F sqlite3.1 3d8b83c91651f53472ca17599dae3457b8b89494
F sqlite3.pc.in 48fed132e7cb71ab676105d2a4dc77127d8c1f3a
F src/alter.c b00900877f766f116f9e16116f1ccacdc21d82f1
F src/analyze.c e8c8a9d20beb2ad156321330e8f4fea002d8deee
F src/analyze.c ec6e0691a6a23e0239dc733109b906ee04b89cc3
F src/attach.c 3801129015ef59d76bf23c95ef9b0069d18a0c52
F src/auth.c 523da7fb4979469955d822ff9298352d6b31de34
F src/backup.c a729e63cf5cd1829507cb7b8e89f99b95141bb53
@ -296,7 +296,7 @@ F src/vtab.c 21b932841e51ebd7d075e2d0ad1415dce8d2d5fd
F src/wal.c 264df50a1b33124130b23180ded2e2c5663c652a
F src/wal.h df01efe09c5cb8c8e391ff1715cca294f89668a4
F src/walker.c 11edb74d587bc87b33ca96a5173e3ec1b8389e45
F src/where.c 7b9e13cff91a2f14ac61e6a1bc3a83b5113e6298
F src/where.c 2bc0226fced128686c432748324351beb127829b
F src/whereInt.h 929c1349b5355fd44f22cee5c14d72b3329c58a6
F test/8_3_names.test ebbb5cd36741350040fd28b432ceadf495be25b2
F test/aggerror.test a867e273ef9e3d7919f03ef4f0e8c0d2767944f2
@ -316,7 +316,7 @@ F test/analyze5.test 765c4e284aa69ca172772aa940946f55629bc8c4
F test/analyze6.test d31defa011a561b938b4608d3538c1b4e0b5e92c
F test/analyze7.test bb1409afc9e8629e414387ef048b8e0e3e0bdc4f
F test/analyze8.test 093d15c1c888eed5034304a98c992f7360130b88
F test/analyze9.test 623e02a99a78fa12fe5def2fd559032d5d887e0f
F test/analyze9.test 93619368fff2db833747a6dfa9b1146a82e5d4d2
F test/analyzeA.test 1a5c40079894847976d983ca39c707aaa44b6944
F test/analyzeB.test 8bf35ee0a548aea831bf56762cb8e7fdb1db083d
F test/async.test 1d0e056ba1bb9729283a0f22718d3a25e82c277b
@ -1122,7 +1122,7 @@ F test/win32longpath.test 169c75a3b2e43481f4a62122510210c67b08f26d
F test/with1.test 268081a6b14817a262ced4d0ee34d4d2a1dd2068
F test/with2.test ee227a663586aa09771cafd4fa269c5217eaf775
F test/withM.test e97f2a8c506ab3ea9eab94e6f6072f6cc924c991
F test/without_rowid1.test e00a0a9dc9f0be651f011d61e8a32b7add5afb30
F test/without_rowid1.test 7862e605753c8d25329f665fa09072e842183151
F test/without_rowid2.test af260339f79d13cb220288b67cd287fbcf81ad99
F test/without_rowid3.test eac3d5c8a1924725b58503a368f2cbd24fd6c8a0
F test/without_rowid4.test 4e08bcbaee0399f35d58b5581881e7a6243d458a
@ -1181,7 +1181,8 @@ F tool/vdbe_profile.tcl 67746953071a9f8f2f668b73fe899074e2c6d8c1
F tool/warnings-clang.sh f6aa929dc20ef1f856af04a730772f59283631d4
F tool/warnings.sh 0abfd78ceb09b7f7c27c688c8e3fe93268a13b32
F tool/win/sqlite.vsix deb315d026cc8400325c5863eef847784a219a2f
P fb32e374b75b160e7b535e732ced6c34dbb513eb
R 46fc4bdeeae8d59d2e02be8ec2b2e5ac
P 6f86d89b8800c50035da7809bff941d08a33a6a2 053a210e3169732c58f84cb54c9b6f6df3a8f4ea
R 48fee5f306f007e5e5bc0779449b568d
T +closed 053a210e3169732c58f84cb54c9b6f6df3a8f4ea
U drh
Z cf9f7f35abbae67619fbb464751389eb
Z b0031b3eff85f5d5ff26a8a2fea67c94

View File

@ -1 +1 @@
6f86d89b8800c50035da7809bff941d08a33a6a2
bc2de8095fa9c385db0adf22ca55b0298a33c284

View File

@ -246,6 +246,7 @@ static void openStatTable(
assert( i<ArraySize(aTable) );
sqlite3VdbeAddOp4Int(v, OP_OpenWrite, iStatCur+i, aRoot[i], iDb, 3);
sqlite3VdbeChangeP5(v, aCreateTbl[i]);
VdbeComment((v, aTable[i].zName));
}
}
@ -281,7 +282,8 @@ struct Stat4Sample {
struct Stat4Accum {
tRowcnt nRow; /* Number of rows in the entire table */
tRowcnt nPSample; /* How often to do a periodic sample */
int nCol; /* Number of columns in index + rowid */
int nCol; /* Number of columns in index + pk/rowid */
int nKeyCol; /* Number of index columns w/o the pk/rowid */
int mxSample; /* Maximum number of samples to accumulate */
Stat4Sample current; /* Current row as a Stat4Sample */
u32 iPrn; /* Pseudo-random number used for sampling */
@ -367,9 +369,17 @@ static void stat4Destructor(void *pOld){
}
/*
** Implementation of the stat_init(N,C) SQL function. The two parameters
** are the number of rows in the table or index (C) and the number of columns
** in the index (N). The second argument (C) is only used for STAT3 and STAT4.
** Implementation of the stat_init(N,K,C) SQL function. The three parameters
** are:
** N: The number of columns in the index including the rowid/pk
** K: The number of columns in the index excluding the rowid/pk
** C: The number of rows in the index
**
** C is only used for STAT3 and STAT4.
**
** For ordinary rowid tables, N==K+1. But for WITHOUT ROWID tables,
** N=K+P where P is the number of columns in the primary key. For the
** covering index that implements the original WITHOUT ROWID table, N==K.
**
** This routine allocates the Stat4Accum object in heap memory. The return
** value is a pointer to the the Stat4Accum object encoded as a blob (i.e.
@ -382,6 +392,7 @@ static void statInit(
){
Stat4Accum *p;
int nCol; /* Number of columns in index being sampled */
int nKeyCol; /* Number of key columns */
int nColUp; /* nCol rounded up for alignment */
int n; /* Bytes of space to allocate */
sqlite3 *db; /* Database connection */
@ -392,8 +403,11 @@ static void statInit(
/* Decode the three function arguments */
UNUSED_PARAMETER(argc);
nCol = sqlite3_value_int(argv[0]);
assert( nCol>1 ); /* >1 because it includes the rowid column */
assert( nCol>0 );
nColUp = sizeof(tRowcnt)<8 ? (nCol+1)&~1 : nCol;
nKeyCol = sqlite3_value_int(argv[1]);
assert( nKeyCol<=nCol );
assert( nKeyCol>0 );
/* Allocate the space required for the Stat4Accum object */
n = sizeof(*p)
@ -415,6 +429,7 @@ static void statInit(
p->db = db;
p->nRow = 0;
p->nCol = nCol;
p->nKeyCol = nKeyCol;
p->current.anDLt = (tRowcnt*)&p[1];
p->current.anEq = &p->current.anDLt[nColUp];
@ -425,9 +440,9 @@ static void statInit(
p->iGet = -1;
p->mxSample = mxSample;
p->nPSample = (tRowcnt)(sqlite3_value_int64(argv[1])/(mxSample/3+1) + 1);
p->nPSample = (tRowcnt)(sqlite3_value_int64(argv[2])/(mxSample/3+1) + 1);
p->current.anLt = &p->current.anEq[nColUp];
p->iPrn = nCol*0x689e962d ^ sqlite3_value_int(argv[1])*0xd0944565;
p->iPrn = nCol*0x689e962d ^ sqlite3_value_int(argv[2])*0xd0944565;
/* Set up the Stat4Accum.a[] and aBest[] arrays */
p->a = (struct Stat4Sample*)&p->current.anLt[nColUp];
@ -450,7 +465,7 @@ static void statInit(
sqlite3_result_blob(context, p, sizeof(p), stat4Destructor);
}
static const FuncDef statInitFuncdef = {
1+IsStat34, /* nArg */
2+IsStat34, /* nArg */
SQLITE_UTF8, /* funcFlags */
0, /* pUserData */
0, /* pNext */
@ -691,7 +706,7 @@ static void statPush(
UNUSED_PARAMETER( argc );
UNUSED_PARAMETER( context );
assert( p->nCol>1 ); /* Includes rowid field */
assert( p->nCol>0 );
assert( iChng<p->nCol );
if( p->nRow==0 ){
@ -819,7 +834,7 @@ static void statGet(
char *z;
int i;
char *zRet = sqlite3MallocZero(p->nCol * 25);
char *zRet = sqlite3MallocZero( (p->nKeyCol+1)*25 );
if( zRet==0 ){
sqlite3_result_error_nomem(context);
return;
@ -827,7 +842,7 @@ static void statGet(
sqlite3_snprintf(24, zRet, "%llu", (u64)p->nRow);
z = zRet + sqlite3Strlen30(zRet);
for(i=0; i<(p->nCol-1); i++){
for(i=0; i<p->nKeyCol; i++){
u64 nDistinct = p->current.anDLt[i] + 1;
u64 iVal = (p->nRow + nDistinct - 1) / nDistinct;
sqlite3_snprintf(24, z, " %llu", iVal);
@ -996,18 +1011,19 @@ static void analyzeOneTable(
if( pOnlyIdx && pOnlyIdx!=pIdx ) continue;
if( pIdx->pPartIdxWhere==0 ) needTableCnt = 0;
VdbeNoopComment((v, "Begin analysis of %s", pIdx->zName));
nCol = pIdx->nKeyCol;
if( !HasRowid(pTab) && IsPrimaryKeyIndex(pIdx) ){
nCol = pIdx->nKeyCol;
zIdxName = pTab->zName;
}else{
nCol = pIdx->nColumn;
zIdxName = pIdx->zName;
}
aGotoChng = sqlite3DbMallocRaw(db, sizeof(int)*(nCol+1));
if( aGotoChng==0 ) continue;
/* Populate the register containing the index name. */
if( IsPrimaryKeyIndex(pIdx) && !HasRowid(pTab) ){
zIdxName = pTab->zName;
}else{
zIdxName = pIdx->zName;
}
sqlite3VdbeAddOp4(v, OP_String8, 0, regIdxname, 0, zIdxName, 0);
VdbeComment((v, "Analysis for %s.%s", pTab->zName, zIdxName));
/*
** Pseudo-code for loop that calls stat_push():
@ -1061,12 +1077,13 @@ static void analyzeOneTable(
** The second argument is only used for STAT3 and STAT4
*/
#ifdef SQLITE_ENABLE_STAT3_OR_STAT4
sqlite3VdbeAddOp2(v, OP_Count, iIdxCur, regStat4+2);
sqlite3VdbeAddOp2(v, OP_Count, iIdxCur, regStat4+3);
#endif
sqlite3VdbeAddOp2(v, OP_Integer, nCol+1, regStat4+1);
sqlite3VdbeAddOp2(v, OP_Integer, nCol, regStat4+1);
sqlite3VdbeAddOp2(v, OP_Integer, pIdx->nKeyCol, regStat4+2);
sqlite3VdbeAddOp3(v, OP_Function, 0, regStat4+1, regStat4);
sqlite3VdbeChangeP4(v, -1, (char*)&statInitFuncdef, P4_FUNCDEF);
sqlite3VdbeChangeP5(v, 1+IsStat34);
sqlite3VdbeChangeP5(v, 2+IsStat34);
/* Implementation of the following:
**
@ -1168,7 +1185,7 @@ static void analyzeOneTable(
int addrIsNull;
u8 seekOp = HasRowid(pTab) ? OP_NotExists : OP_NotFound;
pParse->nMem = MAX(pParse->nMem, regCol+nCol+1);
pParse->nMem = MAX(pParse->nMem, regCol+nCol);
addrNext = sqlite3VdbeCurrentAddr(v);
callStatGet(v, regStat4, STAT_GET_ROWID, regSampleRowid);
@ -1190,7 +1207,7 @@ static void analyzeOneTable(
i16 iCol = pIdx->aiColumn[i];
sqlite3ExprCodeGetColumnOfTable(v, pTab, iTabCur, iCol, regCol+i);
}
sqlite3VdbeAddOp3(v, OP_MakeRecord, regCol, nCol+1, regSample);
sqlite3VdbeAddOp3(v, OP_MakeRecord, regCol, nCol, regSample);
#endif
sqlite3VdbeAddOp3(v, OP_MakeRecord, regTabname, 6, regTemp);
sqlite3VdbeAddOp2(v, OP_NewRowid, iStatCur+1, regNewRowid);

View File

@ -544,7 +544,7 @@ static WhereTerm *whereScanInit(
if( pIdx && iColumn>=0 ){
pScan->idxaff = pIdx->pTable->aCol[iColumn].affinity;
for(j=0; pIdx->aiColumn[j]!=iColumn; j++){
if( NEVER(j>=pIdx->nKeyCol) ) return 0;
if( NEVER(j>pIdx->nColumn) ) return 0;
}
pScan->zCollName = pIdx->azColl[j];
}else{
@ -2201,7 +2201,7 @@ static int whereEqualScanEst(
int bOk;
assert( nEq>=1 );
assert( nEq<=(p->nKeyCol+1) );
assert( nEq<=p->nColumn );
assert( p->aSample!=0 );
assert( p->nSample>0 );
assert( pBuilder->nRecValid<nEq );
@ -2214,7 +2214,7 @@ static int whereEqualScanEst(
/* This is an optimization only. The call to sqlite3Stat4ProbeSetValue()
** below would return the same value. */
if( nEq>p->nKeyCol ){
if( nEq>=p->nColumn ){
*pnRow = 1;
return SQLITE_OK;
}
@ -2645,7 +2645,7 @@ static char *explainIndexRange(sqlite3 *db, WhereLoop *pLoop, Table *pTab){
txt.db = db;
sqlite3StrAccumAppend(&txt, " (", 2);
for(i=0; i<nEq; i++){
char *z = (i==pIndex->nKeyCol ) ? "rowid" : aCol[aiColumn[i]].zName;
char *z = aiColumn[i] < 0 ? "rowid" : aCol[aiColumn[i]].zName;
if( i>=nSkip ){
explainAppendTerm(&txt, i, z, "=");
}else{
@ -2658,11 +2658,11 @@ static char *explainIndexRange(sqlite3 *db, WhereLoop *pLoop, Table *pTab){
j = i;
if( pLoop->wsFlags&WHERE_BTM_LIMIT ){
char *z = (j==pIndex->nKeyCol ) ? "rowid" : aCol[aiColumn[j]].zName;
char *z = aiColumn[j] < 0 ? "rowid" : aCol[aiColumn[j]].zName;
explainAppendTerm(&txt, i++, z, ">");
}
if( pLoop->wsFlags&WHERE_TOP_LIMIT ){
char *z = (j==pIndex->nKeyCol ) ? "rowid" : aCol[aiColumn[j]].zName;
char *z = aiColumn[j] < 0 ? "rowid" : aCol[aiColumn[j]].zName;
explainAppendTerm(&txt, i, z, "<");
}
sqlite3StrAccumAppend(&txt, ")", 1);
@ -4164,12 +4164,9 @@ static int whereLoopAddBtreeIndex(
}
if( pProbe->bUnordered ) opMask &= ~(WO_GT|WO_GE|WO_LT|WO_LE);
assert( pNew->u.btree.nEq<=pProbe->nKeyCol );
if( pNew->u.btree.nEq < pProbe->nKeyCol ){
iCol = pProbe->aiColumn[pNew->u.btree.nEq];
}else{
iCol = -1;
}
assert( pNew->u.btree.nEq<pProbe->nColumn );
iCol = pProbe->aiColumn[pNew->u.btree.nEq];
pTerm = whereScanInit(&scan, pBuilder->pWC, pSrc->iCursor, iCol,
opMask, pProbe);
saved_nEq = pNew->u.btree.nEq;
@ -4359,7 +4356,7 @@ static int whereLoopAddBtreeIndex(
}
if( (pNew->wsFlags & WHERE_TOP_LIMIT)==0
&& pNew->u.btree.nEq<(pProbe->nKeyCol + (pProbe->zName!=0))
&& pNew->u.btree.nEq<pProbe->nColumn
){
whereLoopAddBtreeIndex(pBuilder, pSrc, pProbe, nInMul+nIn);
}
@ -4506,6 +4503,7 @@ static int whereLoopAddBtree(
Index *pFirst; /* First of real indices on the table */
memset(&sPk, 0, sizeof(Index));
sPk.nKeyCol = 1;
sPk.nColumn = 1;
sPk.aiColumn = &aiColumnPk;
sPk.aiRowLogEst = aiRowEstPk;
sPk.onError = OE_Replace;

View File

@ -953,4 +953,72 @@ for {set i 0} {$i<16} {incr i} {
} {1}
}
#-------------------------------------------------------------------------
#
reset_db
do_execsql_test 21.0 {
CREATE TABLE t2(a, b);
CREATE INDEX i2 ON t2(a);
}
do_test 21.1 {
for {set i 1} {$i < 100} {incr i} {
execsql {
INSERT INTO t2 VALUES(CASE WHEN $i < 80 THEN 'one' ELSE 'two' END, $i)
}
}
execsql ANALYZE
} {}
# Condition (a='one') matches 80% of the table. (rowid<10) reduces this to
# 10%, but (rowid<50) only reduces it to 50%. So in the first case below
# the index is used. In the second, it is not.
#
do_eqp_test 21.2 {
SELECT * FROM t2 WHERE a='one' AND rowid < 10
} {/*USING INDEX i2 (a=? AND rowid<?)*/}
do_eqp_test 21.3 {
SELECT * FROM t2 WHERE a='one' AND rowid < 50
} {/*USING INTEGER PRIMARY KEY*/}
#-------------------------------------------------------------------------
#
reset_db
do_execsql_test 22.0 {
CREATE TABLE t3(a, b, c, d, PRIMARY KEY(a, b)) WITHOUT ROWID;
}
do_execsql_test 22.1 {
WITH r(x) AS (
SELECT 1
UNION ALL
SELECT x+1 FROM r WHERE x<=100
)
INSERT INTO t3 SELECT
CASE WHEN (x>45 AND x<96) THEN 'B' ELSE 'A' END, /* Column "a" */
x, /* Column "b" */
CASE WHEN (x<51) THEN 'one' ELSE 'two' END, /* Column "c" */
x /* Column "d" */
FROM r;
CREATE INDEX i3 ON t3(c);
CREATE INDEX i4 ON t3(d);
ANALYZE;
}
# Expression (c='one' AND a='B') matches 5 table rows. But (c='one' AND a=A')
# matches 45. Expression (d<?) matches 20. Neither index is a covering index.
#
# Therefore, with stat4 data, SQLite prefers (c='one' AND a='B') over (d<20),
# and (d<20) over (c='one' AND a='A').
foreach {tn where res} {
1 "c='one' AND a='B' AND d < 20" {/*INDEX i3 (c=? AND a=?)*/}
2 "c='one' AND a='A' AND d < 20" {/*INDEX i4 (d<?)*/}
} {
do_eqp_test 22.2.$tn "SELECT * FROM t3 WHERE $where" $res
}
finish_test

View File

@ -213,5 +213,69 @@ do_execsql_test 4.1 {
do_execsql_test 4.2 {
SELECT t42.rowid FROM t42, t41;
} {1}
#--------------------------------------------------------------------------
# The following tests verify that the trailing PK fields added to each
# entry in an index on a WITHOUT ROWID table are used correctly.
#
do_execsql_test 5.0 {
CREATE TABLE t45(a PRIMARY KEY, b, c) WITHOUT ROWID;
CREATE INDEX i45 ON t45(b);
INSERT INTO t45 VALUES(2, 'one', 'x');
INSERT INTO t45 VALUES(4, 'one', 'x');
INSERT INTO t45 VALUES(6, 'one', 'x');
INSERT INTO t45 VALUES(8, 'one', 'x');
INSERT INTO t45 VALUES(10, 'one', 'x');
INSERT INTO t45 VALUES(1, 'two', 'x');
INSERT INTO t45 VALUES(3, 'two', 'x');
INSERT INTO t45 VALUES(5, 'two', 'x');
INSERT INTO t45 VALUES(7, 'two', 'x');
INSERT INTO t45 VALUES(9, 'two', 'x');
}
do_eqp_test 5.1 {
SELECT * FROM t45 WHERE b=? AND a>?
} {/*USING INDEX i45 (b=? AND a>?)*/}
do_execsql_test 5.2 {
SELECT * FROM t45 WHERE b='two' AND a>4
} {5 two x 7 two x 9 two x}
do_execsql_test 5.3 {
SELECT * FROM t45 WHERE b='one' AND a<8
} { 2 one x 4 one x 6 one x }
do_execsql_test 5.4 {
CREATE TABLE t46(a, b, c, d, PRIMARY KEY(a, b)) WITHOUT ROWID;
WITH r(x) AS (
SELECT 1 UNION ALL SELECT x+1 FROM r WHERE x<100
)
INSERT INTO t46 SELECT x / 20, x % 20, x % 10, x FROM r;
}
set queries {
1 2 "c = 5 AND a = 1" {/*i46 (c=? AND a=?)*/}
2 6 "c = 4 AND a < 3" {/*i46 (c=? AND a<?)*/}
3 4 "c = 2 AND a >= 3" {/*i46 (c=? AND a>?)*/}
4 1 "c = 2 AND a = 1 AND b<10" {/*i46 (c=? AND a=? AND b<?)*/}
5 1 "c = 0 AND a = 0 AND b>5" {/*i46 (c=? AND a=? AND b>?)*/}
}
foreach {tn cnt where eqp} $queries {
do_execsql_test 5.5.$tn.1 "SELECT count(*) FROM t46 WHERE $where" $cnt
}
do_execsql_test 5.6 {
CREATE INDEX i46 ON t46(c);
}
foreach {tn cnt where eqp} $queries {
do_execsql_test 5.7.$tn.1 "SELECT count(*) FROM t46 WHERE $where" $cnt
do_eqp_test 5.7.$tn.2 "SELECT count(*) FROM t46 WHERE $where" $eqp
}
finish_test