SQLite

Check-in [5ded9b6838]
Login

Many hyperlinks are disabled.
Use anonymous login to enable hyperlinks.

Overview
Comment:Enhance IN processing to allow efficient use of indices with numeric affinities. Add test cases for IN processing that would have spotted the error in the [2be661a48023f4] check-in.
Downloads: Tarball | ZIP archive
Timelines: family | ancestors | descendants | both | trunk
Files: files | file ages | folders
SHA1: 5ded9b68388f4024425c11f09b03529ac89454ce
User & Date: drh 2012-09-18 19:29:06.434
Context
2012-09-18
23:21
Silence harmless compiler warning seen with SQLITE_OMIT_DEPRECATED. (check-in: c5cee96932 user: mistachkin tags: trunk)
19:29
Enhance IN processing to allow efficient use of indices with numeric affinities. Add test cases for IN processing that would have spotted the error in the [2be661a48023f4] check-in. (check-in: 5ded9b6838 user: drh tags: trunk)
17:08
Enhancements to the comments on sqlite3FindInIndex(). No code changes. (check-in: b1a4c39499 user: drh tags: trunk)
Changes
Unified Diff Ignore Whitespace Patch
Changes to src/expr.c.
1538
1539
1540
1541
1542
1543
1544
1545
1546
1547
1548
1549
1550
1551
1552
1553
      ** to this collation sequence.  */
      CollSeq *pReq = sqlite3BinaryCompareCollSeq(pParse, pX->pLeft, pExpr);

      /* Check that the affinity that will be used to perform the 
      ** comparison is the same as the affinity of the column. If
      ** it is not, it is not possible to use any index.
      */
      char aff = comparisonAffinity(pX);
      int affinity_ok = (pTab->aCol[iCol].affinity==aff||aff==SQLITE_AFF_NONE);

      for(pIdx=pTab->pIndex; pIdx && eType==0 && affinity_ok; pIdx=pIdx->pNext){
        if( (pIdx->aiColumn[0]==iCol)
         && sqlite3FindCollSeq(db, ENC(db), pIdx->azColl[0], 0)==pReq
         && (!mustBeUnique || (pIdx->nColumn==1 && pIdx->onError!=OE_None))
        ){
          int iAddr;







<
|







1538
1539
1540
1541
1542
1543
1544

1545
1546
1547
1548
1549
1550
1551
1552
      ** to this collation sequence.  */
      CollSeq *pReq = sqlite3BinaryCompareCollSeq(pParse, pX->pLeft, pExpr);

      /* Check that the affinity that will be used to perform the 
      ** comparison is the same as the affinity of the column. If
      ** it is not, it is not possible to use any index.
      */

      int affinity_ok = sqlite3IndexAffinityOk(pX, pTab->aCol[iCol].affinity);

      for(pIdx=pTab->pIndex; pIdx && eType==0 && affinity_ok; pIdx=pIdx->pNext){
        if( (pIdx->aiColumn[0]==iCol)
         && sqlite3FindCollSeq(db, ENC(db), pIdx->azColl[0], 0)==pReq
         && (!mustBeUnique || (pIdx->nColumn==1 && pIdx->onError!=OE_None))
        ){
          int iAddr;
Added test/in5.test.




















































































































































































































































































>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
# 2012 September 18
#
# 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.
#
#***********************************************************************
#

set testdir [file dirname $argv0]
source $testdir/tester.tcl

do_test in5-1.1 {
  execsql {
    CREATE TABLE t1x(x INTEGER PRIMARY KEY);
    INSERT INTO t1x VALUES(1),(3),(5),(7),(9);
    CREATE TABLE t1y(y INTEGER UNIQUE);
    INSERT INTO t1y VALUES(2),(4),(6),(8);
    CREATE TABLE t1z(z TEXT UNIQUE);
    INSERT INTO t1z VALUES('a'),('c'),('e'),('g');
    CREATE TABLE t2(a INTEGER, b INTEGER, c TEXT, d TEXT);
    INSERT INTO t2 VALUES(1,2,'a','12a'),(1,2,'b','12b'),
                         (2,3,'g','23g'),(3,5,'c','35c'),
                         (4,6,'h','46h'),(5,6,'e','56e');
    CREATE TABLE t3x AS SELECT x FROM t1x;
    CREATE TABLE t3y AS SELECT y FROM t1y;
    CREATE TABLE t3z AS SELECT z FROM t1z;
    SELECT d FROM t2 WHERE a IN t1x AND b IN t1y AND c IN t1z ORDER BY c;
  }
} {12a 56e}
do_test in5-1.2 {
  execsql {
    SELECT d FROM t2 WHERE a IN t1y AND b IN t1x AND c IN t1z ORDER BY d;
  }
} {23g}
do_test in5-1.3 {
  execsql {
    SELECT d FROM t2 WHERE a IN t3x AND b IN t3y AND c IN t3z ORDER BY d;
  }
} {12a 56e}


do_test in5-2.1 {
  execsql {
    CREATE INDEX t2abc ON t2(a,b,c);
    SELECT d FROM t2 WHERE a IN t1x AND b IN t1y AND c IN t1z ORDER BY d;
  }
} {12a 56e}
do_test in5-2.2 {
  execsql {
    SELECT d FROM t2 WHERE a IN t1y AND b IN t1x AND c IN t1z ORDER BY d;
  }
} {23g}
do_test in5-2.3 {
  regexp {OpenEphemeral} [db eval {
    EXPLAIN SELECT d FROM t2 WHERE a IN t1x AND b IN t1y AND c IN t1z
  }]
} {0}
do_test in5-2.4 {
  execsql {
    SELECT d FROM t2 WHERE a IN t3x AND b IN t3y AND c IN t3z ORDER BY d;
  }
} {12a 56e}
do_test in5-2.5.1 {
  regexp {OpenEphemeral} [db eval {
    EXPLAIN SELECT d FROM t2 WHERE a IN t3x AND b IN t1y AND c IN t1z
  }]
} {1}
do_test in5-2.5.2 {
  regexp {OpenEphemeral} [db eval {
    EXPLAIN SELECT d FROM t2 WHERE a IN t1x AND b IN t3y AND c IN t1z
  }]
} {1}
do_test in5-2.5.3 {
  regexp {OpenEphemeral} [db eval {
    EXPLAIN SELECT d FROM t2 WHERE a IN t1x AND b IN t1y AND c IN t3z
  }]
} {1}

do_test in5-3.1 {
  execsql {
    DROP INDEX t2abc;
    CREATE INDEX t2ab ON t2(a,b);
    SELECT d FROM t2 WHERE a IN t1x AND b IN t1y AND c IN t1z ORDER BY d;
  }
} {12a 56e}
do_test in5-3.2 {
  execsql {
    SELECT d FROM t2 WHERE a IN t1y AND b IN t1x AND c IN t1z ORDER BY d;
  }
} {23g}
do_test in5-3.3 {
  regexp {OpenEphemeral} [db eval {
    EXPLAIN SELECT d FROM t2 WHERE a IN t1x AND b IN t1y AND c IN t1z
  }]
} {0}

do_test in5-4.1 {
  execsql {
    DROP INDEX t2ab;
    CREATE INDEX t2abcd ON t2(a,b,c,d);
    SELECT d FROM t2 WHERE a IN t1x AND b IN t1y AND c IN t1z ORDER BY d;
  }
} {12a 56e}
do_test in5-4.2 {
  execsql {
    SELECT d FROM t2 WHERE a IN t1y AND b IN t1x AND c IN t1z ORDER BY d;
  }
} {23g}
do_test in5-4.3 {
  regexp {OpenEphemeral} [db eval {
    EXPLAIN SELECT d FROM t2 WHERE a IN t1x AND b IN t1y AND c IN t1z
  }]
} {0}


do_test in5-5.1 {
  execsql {
    DROP INDEX t2abcd;
    CREATE INDEX t2cbad ON t2(c,b,a,d);
    SELECT d FROM t2 WHERE a IN t1x AND b IN t1y AND c IN t1z ORDER BY d;
  }
} {12a 56e}
do_test in5-5.2 {
  execsql {
    SELECT d FROM t2 WHERE a IN t1y AND b IN t1x AND c IN t1z ORDER BY d;
  }
} {23g}
do_test in5-5.3 {
  regexp {OpenEphemeral} [db eval {
    EXPLAIN SELECT d FROM t2 WHERE a IN t1x AND b IN t1y AND c IN t1z
  }]
} {0}

finish_test