SQLite

Check-in [ce35e39c]
Login

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

Overview
Comment:Fix a problem with processing "LEFT JOIN tbl ON tbl.a = ? AND (tbl.b=? OR tbl.c=?)" in cases where there are indexes on both tbl(a, b) and tbl(a, c).
Downloads: Tarball | ZIP archive | SQL archive
Timelines: family | ancestors | descendants | both | trunk
Files: files | file ages | folders
SHA3-256: ce35e39c5cc2b00dd6b4a9ffaa9d5eb7d9b862759e87d5f053729de7643eee9c
User & Date: dan 2018-04-24 18:53:24
Context
2018-04-24
18:59
Remove a recently added NEVER() macro from a branch that can be taken in obscure circumstances. (check-in: 2aa21003 user: dan tags: trunk)
18:53
Fix a problem with processing "LEFT JOIN tbl ON tbl.a = ? AND (tbl.b=? OR tbl.c=?)" in cases where there are indexes on both tbl(a, b) and tbl(a, c). (check-in: ce35e39c user: dan tags: trunk)
17:34
Do not attempt to use terms from the WHERE clause to drive indexes on the right table of a LEFT JOIN. Fix for ticket [4ba5abf65c5b0f9a96a7a40cd18b] (check-in: aeb694e3 user: drh tags: trunk)
Changes
Unified Diff Ignore Whitespace Patch
Changes to src/wherecode.c.
1211
1212
1213
1214
1215
1216
1217



1218
1219
1220
1221
1222
1223
1224
  addrBrk = pLevel->addrBrk = pLevel->addrNxt = sqlite3VdbeMakeLabel(v);
  addrCont = pLevel->addrCont = sqlite3VdbeMakeLabel(v);

  /* If this is the right table of a LEFT OUTER JOIN, allocate and
  ** initialize a memory cell that records if this table matches any
  ** row of the left table of the join.
  */



  if( pLevel->iFrom>0 && (pTabItem[0].fg.jointype & JT_LEFT)!=0 ){
    pLevel->iLeftJoin = ++pParse->nMem;
    sqlite3VdbeAddOp2(v, OP_Integer, 0, pLevel->iLeftJoin);
    VdbeComment((v, "init LEFT JOIN no-match flag"));
  }

  /* Compute a safe address to jump to if we discover that the table for







>
>
>







1211
1212
1213
1214
1215
1216
1217
1218
1219
1220
1221
1222
1223
1224
1225
1226
1227
  addrBrk = pLevel->addrBrk = pLevel->addrNxt = sqlite3VdbeMakeLabel(v);
  addrCont = pLevel->addrCont = sqlite3VdbeMakeLabel(v);

  /* If this is the right table of a LEFT OUTER JOIN, allocate and
  ** initialize a memory cell that records if this table matches any
  ** row of the left table of the join.
  */
  assert( (pWInfo->wctrlFlags & WHERE_OR_SUBCLAUSE)
       || pLevel->iFrom>0 || (pTabItem[0].fg.jointype & JT_LEFT)==0
  );
  if( pLevel->iFrom>0 && (pTabItem[0].fg.jointype & JT_LEFT)!=0 ){
    pLevel->iLeftJoin = ++pParse->nMem;
    sqlite3VdbeAddOp2(v, OP_Integer, 0, pLevel->iLeftJoin);
    VdbeComment((v, "init LEFT JOIN no-match flag"));
  }

  /* Compute a safe address to jump to if we discover that the table for
1909
1910
1911
1912
1913
1914
1915
1916
1917
1918
1919
1920
1921
1922
1923
    ** See ticket http://www.sqlite.org/src/info/f2369304e4
    */
    if( pWC->nTerm>1 ){
      int iTerm;
      for(iTerm=0; iTerm<pWC->nTerm; iTerm++){
        Expr *pExpr = pWC->a[iTerm].pExpr;
        if( &pWC->a[iTerm] == pTerm ) continue;
        if( ExprHasProperty(pExpr, EP_FromJoin) ) continue;
        testcase( pWC->a[iTerm].wtFlags & TERM_VIRTUAL );
        testcase( pWC->a[iTerm].wtFlags & TERM_CODED );
        if( (pWC->a[iTerm].wtFlags & (TERM_VIRTUAL|TERM_CODED))!=0 ) continue;
        if( (pWC->a[iTerm].eOperator & WO_ALL)==0 ) continue;
        testcase( pWC->a[iTerm].wtFlags & TERM_ORINFO );
        pExpr = sqlite3ExprDup(db, pExpr, 0);
        pAndExpr = sqlite3ExprAnd(db, pAndExpr, pExpr);







<







1912
1913
1914
1915
1916
1917
1918

1919
1920
1921
1922
1923
1924
1925
    ** See ticket http://www.sqlite.org/src/info/f2369304e4
    */
    if( pWC->nTerm>1 ){
      int iTerm;
      for(iTerm=0; iTerm<pWC->nTerm; iTerm++){
        Expr *pExpr = pWC->a[iTerm].pExpr;
        if( &pWC->a[iTerm] == pTerm ) continue;

        testcase( pWC->a[iTerm].wtFlags & TERM_VIRTUAL );
        testcase( pWC->a[iTerm].wtFlags & TERM_CODED );
        if( (pWC->a[iTerm].wtFlags & (TERM_VIRTUAL|TERM_CODED))!=0 ) continue;
        if( (pWC->a[iTerm].eOperator & WO_ALL)==0 ) continue;
        testcase( pWC->a[iTerm].wtFlags & TERM_ORINFO );
        pExpr = sqlite3ExprDup(db, pExpr, 0);
        pAndExpr = sqlite3ExprAnd(db, pAndExpr, pExpr);
1934
1935
1936
1937
1938
1939
1940

1941


1942
1943
1944
1945
1946
1947
1948
    wctrlFlags =  WHERE_OR_SUBCLAUSE | (pWInfo->wctrlFlags & WHERE_SEEK_TABLE);
    for(ii=0; ii<pOrWc->nTerm; ii++){
      WhereTerm *pOrTerm = &pOrWc->a[ii];
      if( pOrTerm->leftCursor==iCur || (pOrTerm->eOperator & WO_AND)!=0 ){
        WhereInfo *pSubWInfo;           /* Info for single OR-term scan */
        Expr *pOrExpr = pOrTerm->pExpr; /* Current OR clause term */
        int jmp1 = 0;                   /* Address of jump operation */

        if( pAndExpr && !ExprHasProperty(pOrExpr, EP_FromJoin) ){


          pAndExpr->pLeft = pOrExpr;
          pOrExpr = pAndExpr;
        }
        /* Loop through table entries that match term pOrTerm. */
        WHERETRACE(0xffff, ("Subplan for OR-clause:\n"));
        pSubWInfo = sqlite3WhereBegin(pParse, pOrTab, pOrExpr, 0, 0,
                                      wctrlFlags, iCovCur);







>
|
>
>







1936
1937
1938
1939
1940
1941
1942
1943
1944
1945
1946
1947
1948
1949
1950
1951
1952
1953
    wctrlFlags =  WHERE_OR_SUBCLAUSE | (pWInfo->wctrlFlags & WHERE_SEEK_TABLE);
    for(ii=0; ii<pOrWc->nTerm; ii++){
      WhereTerm *pOrTerm = &pOrWc->a[ii];
      if( pOrTerm->leftCursor==iCur || (pOrTerm->eOperator & WO_AND)!=0 ){
        WhereInfo *pSubWInfo;           /* Info for single OR-term scan */
        Expr *pOrExpr = pOrTerm->pExpr; /* Current OR clause term */
        int jmp1 = 0;                   /* Address of jump operation */
        assert( (pTabItem[0].fg.jointype & JT_LEFT)==0 
             || ExprHasProperty(pOrExpr, EP_FromJoin) 
        );
        if( pAndExpr ){
          pAndExpr->pLeft = pOrExpr;
          pOrExpr = pAndExpr;
        }
        /* Loop through table entries that match term pOrTerm. */
        WHERETRACE(0xffff, ("Subplan for OR-clause:\n"));
        pSubWInfo = sqlite3WhereBegin(pParse, pOrTab, pOrExpr, 0, 0,
                                      wctrlFlags, iCovCur);
2117
2118
2119
2120
2121
2122
2123
2124
2125
2126
2127
2128
2129
2130
2131
        testcase( pWInfo->untestedTerms==0
            && (pWInfo->wctrlFlags & WHERE_OR_SUBCLAUSE)!=0 );
        pWInfo->untestedTerms = 1;
        continue;
      }
      pE = pTerm->pExpr;
      assert( pE!=0 );
      if( pLevel->iLeftJoin && !ExprHasProperty(pE, EP_FromJoin) ){
        continue;
      }
      
      if( iLoop==1 && !sqlite3ExprCoveredByIndex(pE, pLevel->iTabCur, pIdx) ){
        iNext = 2;
        continue;
      }







|







2122
2123
2124
2125
2126
2127
2128
2129
2130
2131
2132
2133
2134
2135
2136
        testcase( pWInfo->untestedTerms==0
            && (pWInfo->wctrlFlags & WHERE_OR_SUBCLAUSE)!=0 );
        pWInfo->untestedTerms = 1;
        continue;
      }
      pE = pTerm->pExpr;
      assert( pE!=0 );
      if( (pTabItem->fg.jointype&JT_LEFT) && !ExprHasProperty(pE,EP_FromJoin) ){
        continue;
      }
      
      if( iLoop==1 && !sqlite3ExprCoveredByIndex(pE, pLevel->iTabCur, pIdx) ){
        iNext = 2;
        continue;
      }
Changes to test/join5.test.
236
237
238
239
240
241
242
















































243
244
245
  SELECT ifnull(z, '!!!') FROM t3 LEFT JOIN t4 ON (x=y);
} {!!!}

do_execsql_test 6.3.2 {
  CREATE INDEX t4i ON t4(y, ifnull(z, '!!!'));
  SELECT ifnull(z, '!!!') FROM t3 LEFT JOIN t4 ON (x=y);
} {!!!}

















































finish_test








>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>



236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
  SELECT ifnull(z, '!!!') FROM t3 LEFT JOIN t4 ON (x=y);
} {!!!}

do_execsql_test 6.3.2 {
  CREATE INDEX t4i ON t4(y, ifnull(z, '!!!'));
  SELECT ifnull(z, '!!!') FROM t3 LEFT JOIN t4 ON (x=y);
} {!!!}

#-------------------------------------------------------------------------
#
reset_db
do_execsql_test 7.0 {
  CREATE TABLE t1(x);
  INSERT INTO t1 VALUES(1);
}

do_execsql_test 7.1 {
  CREATE TABLE t2(x, y, z);
  CREATE INDEX t2xy ON t2(x, y);
  WITH s(i) AS (
    SELECT 1 UNION ALL SELECT i+1 FROM s WHERE i<50000
  )
  INSERT INTO t2 SELECT i/10, i, NULL FROM s;
  ANALYZE;
}

do_eqp_test 7.2 {
  SELECT * FROM t1 LEFT JOIN t2 ON (
    t2.x = t1.x AND (t2.y=? OR (t2.y=? AND t2.z IS NOT NULL))
  );
} {
  0 0 0 {SCAN TABLE t1} 
  0 1 1 {SEARCH TABLE t2 USING INDEX t2xy (x=? AND y=?)} 
  0 1 1 {SEARCH TABLE t2 USING INDEX t2xy (x=? AND y=?)}
}

do_execsql_test 7.3 {
  CREATE TABLE t3(x);

  CREATE TABLE t4(x, y, z);
  CREATE INDEX t4xy ON t4(x, y);
  CREATE INDEX t4xz ON t4(x, z);

  WITH s(i) AS ( SELECT 1 UNION ALL SELECT i+1 FROM s WHERE i<50000)
  INSERT INTO t4 SELECT i/10, i, i FROM s;

  ANALYZE;
}

do_eqp_test 7.4 {
  SELECT * FROM t3 LEFT JOIN t4 ON (t4.x = t3.x) WHERE (t4.y = ? OR t4.z = ?);
} {
  0 0 0 {SCAN TABLE t3} 
  0 1 1 {SEARCH TABLE t4 USING INDEX t4xz (x=?)}
} 

finish_test