/ Check-in [a9daf3ac]
Login

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

Overview
Comment:Fix a problem causing an inaccurate stat4-based estimate for the number of rows visited by a range scan.
Downloads: Tarball | ZIP archive | SQL archive
Timelines: family | ancestors | descendants | both | trunk
Files: files | file ages | folders
SHA1:a9daf3ac444b896013f4054051937d49a597624a
User & Date: drh 2014-08-28 17:30:28
Context
2014-08-28
19:38
Improved WHERETRACE messages for the estimated output row reductions from range scans. check-in: fdd478bb user: drh tags: trunk
17:30
Fix a problem causing an inaccurate stat4-based estimate for the number of rows visited by a range scan. check-in: a9daf3ac user: drh tags: trunk
17:20
Add a testcase() macro to help verfity the row estimation logic. Closed-Leaf check-in: 6ba60952 user: drh tags: stat4-experimental
13:42
Fix a formatting error ("%d" needed in place of "%g") on a WHERETRACE macro inside of the query planner. This fix applies to debugging logic only. check-in: c931ca2b user: drh tags: trunk
Changes
Hide Diffs Unified Diffs Ignore Whitespace Patch

Changes to src/where.c.

2187
2188
2189
2190
2191
2192
2193




2194
2195
2196
2197
2198
2199
2200
      ** less than the upper bound of the range query. Where the upper bound
      ** is either ($P) or ($P:$U). Again, even if $U is available, both values
      ** of iUpper are requested of whereKeyStats() and the smaller used.
      */
      tRowcnt iLower;
      tRowcnt iUpper;





      if( nEq==p->nKeyCol ){
        aff = SQLITE_AFF_INTEGER;
      }else{
        aff = p->pTable->aCol[p->aiColumn[nEq]].affinity;
      }
      /* Determine iLower and iUpper using ($P) only. */
      if( nEq==0 ){







>
>
>
>







2187
2188
2189
2190
2191
2192
2193
2194
2195
2196
2197
2198
2199
2200
2201
2202
2203
2204
      ** less than the upper bound of the range query. Where the upper bound
      ** is either ($P) or ($P:$U). Again, even if $U is available, both values
      ** of iUpper are requested of whereKeyStats() and the smaller used.
      */
      tRowcnt iLower;
      tRowcnt iUpper;

      if( pRec ){
        testcase( pRec->nField!=pBuilder->nRecValid );
        pRec->nField = pBuilder->nRecValid;
      }
      if( nEq==p->nKeyCol ){
        aff = SQLITE_AFF_INTEGER;
      }else{
        aff = p->pTable->aCol[p->aiColumn[nEq]].affinity;
      }
      /* Determine iLower and iUpper using ($P) only. */
      if( nEq==0 ){

Changes to test/whereJ.test.

366
367
368
369
370
371
372
373

374














































375
     AND t0b.id=2
     AND t1b.id BETWEEN t0b.minChild AND t0b.maxChild
     AND t2b.id BETWEEN t1b.minChild AND t1b.maxChild
     AND t3b.id BETWEEN t2b.minChild AND t2b.maxChild
     AND t4.id BETWEEN t3a.minChild AND t3b.maxChild
  ORDER BY t4.x;
} {~/SCAN/}

















































finish_test








>

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

366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
     AND t0b.id=2
     AND t1b.id BETWEEN t0b.minChild AND t0b.maxChild
     AND t2b.id BETWEEN t1b.minChild AND t1b.maxChild
     AND t3b.id BETWEEN t2b.minChild AND t2b.maxChild
     AND t4.id BETWEEN t3a.minChild AND t3b.maxChild
  ORDER BY t4.x;
} {~/SCAN/}

############################################################################

ifcapable stat4 {
  # Create and populate table.
  do_execsql_test 3.1 { CREATE TABLE t1(a, b, c) }
  for {set i 0} {$i < 32} {incr i 2} {
    for {set x 0} {$x < 100} {incr x} {
      execsql { INSERT INTO t1 VALUES($i, $x, $c) }
      incr c
    }
    execsql { INSERT INTO t1 VALUES($i+1, 5, $c) }
    incr c
  }
  
  do_execsql_test 3.2 {
    SELECT a, count(*) FROM t1 GROUP BY a HAVING a < 8;
  } {
    0 100 1 1 2 100 3 1 4 100 5 1 6 100 7 1
  }
  
  do_execsql_test 3.3 {
    CREATE INDEX idx_ab ON t1(a, b);
    CREATE INDEX idx_c ON t1(c);
    ANALYZE;
  } {}
  
  # This one should use index "idx_c".
  do_eqp_test 3.4 {
    SELECT * FROM t1 WHERE 
      a = 4 AND b BETWEEN 20 AND 80           -- Matches 80 rows
        AND
      c BETWEEN 150 AND 160                   -- Matches 10 rows
  } {
    0 0 0 {SEARCH TABLE t1 USING INDEX idx_c (c>? AND c<?)}
  }
  
  # This one should use index "idx_ab".
  do_eqp_test 3.5 {
    SELECT * FROM t1 WHERE 
      a = 5 AND b BETWEEN 20 AND 80           -- Matches 1 row
        AND
      c BETWEEN 150 AND 160                   -- Matches 10 rows
  } {
    0 0 0 {SEARCH TABLE t1 USING INDEX idx_ab (a=? AND b>? AND b<?)}
  }
}


finish_test