SQLite

Check-in [65553ff34b]
Login

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

Overview
Comment:Rollback some of the previous changes in the branch such that the estimated row sizes are now only used as a tie-breaker for index scans.
Downloads: Tarball | ZIP archive
Timelines: family | ancestors | descendants | both | row-size-est
Files: files | file ages | folders
SHA1: 65553ff34b41e54d129ff2fee96be714105503c4
User & Date: drh 2013-10-08 20:42:41.270
Context
2013-10-08
22:25
Fix test cases for the new information in PRAGMA index_list. (check-in: dd03be1065 user: drh tags: row-size-est)
20:42
Rollback some of the previous changes in the branch such that the estimated row sizes are now only used as a tie-breaker for index scans. (check-in: 65553ff34b user: drh tags: row-size-est)
20:01
Use #ifdefs to omit unused code in the columnType() routine depending on compile-time options. (check-in: 3fd5e33217 user: drh tags: row-size-est)
Changes
Unified Diff Ignore Whitespace Patch
Changes to src/where.c.
4334
4335
4336
4337
4338
4339
4340
4341
4342
4343
4344
4345
4346
4347
4348
4349
4350
4351
4352
4353
      pBtm = (pNew->wsFlags & WHERE_BTM_LIMIT)!=0 ?
                     pNew->aLTerm[pNew->nLTerm-2] : 0;
    }
    if( pNew->wsFlags & WHERE_COLUMN_RANGE ){
      /* Adjust nOut and rRun for STAT3 range values */
      assert( pNew->nOut==saved_nOut );
      whereRangeScanEst(pParse, pBuilder, pBtm, pTop, pNew);

      /* If the range constraint is the only constraint on the index and
      ** if the range constraint does not reduce the search space,
      ** then this is really just an index scan which has already
      ** been analyzed. */
      if( pNew->nOut>=saved_nOut && pNew->u.btree.nEq==0 ) continue;
    }
#ifdef SQLITE_ENABLE_STAT3_OR_STAT4
    if( nInMul==0 
     && pProbe->nSample 
     && pNew->u.btree.nEq<=pProbe->nSampleCol
     && OptimizationEnabled(db, SQLITE_Stat3) 
    ){







<
<
<
<
<
<







4334
4335
4336
4337
4338
4339
4340






4341
4342
4343
4344
4345
4346
4347
      pBtm = (pNew->wsFlags & WHERE_BTM_LIMIT)!=0 ?
                     pNew->aLTerm[pNew->nLTerm-2] : 0;
    }
    if( pNew->wsFlags & WHERE_COLUMN_RANGE ){
      /* Adjust nOut and rRun for STAT3 range values */
      assert( pNew->nOut==saved_nOut );
      whereRangeScanEst(pParse, pBuilder, pBtm, pTop, pNew);






    }
#ifdef SQLITE_ENABLE_STAT3_OR_STAT4
    if( nInMul==0 
     && pProbe->nSample 
     && pNew->u.btree.nEq<=pProbe->nSampleCol
     && OptimizationEnabled(db, SQLITE_Stat3) 
    ){
4370
4371
4372
4373
4374
4375
4376
4377
4378
4379
4380
4381
4382
4383
4384
#endif
    if( (pNew->wsFlags & (WHERE_IDX_ONLY|WHERE_IPK))==0 ){
      /* Each row involves a step of the index, then a binary search of
      ** the main table */
      pNew->rRun =  sqlite3LogEstAdd(pNew->rRun,rLogSize>27 ? rLogSize-17 : 10);
    }
    /* Step cost for each output row */
    pNew->rRun = sqlite3LogEstAdd(pNew->rRun, pNew->nOut) + pProbe->szIdxRow;
    whereLoopOutputAdjust(pBuilder->pWC, pNew, pSrc->iCursor);
    rc = whereLoopInsert(pBuilder, pNew);
    if( (pNew->wsFlags & WHERE_TOP_LIMIT)==0
     && pNew->u.btree.nEq<(pProbe->nColumn + (pProbe->zName!=0))
    ){
      whereLoopAddBtreeIndex(pBuilder, pSrc, pProbe, nInMul+nIn);
    }







|







4364
4365
4366
4367
4368
4369
4370
4371
4372
4373
4374
4375
4376
4377
4378
#endif
    if( (pNew->wsFlags & (WHERE_IDX_ONLY|WHERE_IPK))==0 ){
      /* Each row involves a step of the index, then a binary search of
      ** the main table */
      pNew->rRun =  sqlite3LogEstAdd(pNew->rRun,rLogSize>27 ? rLogSize-17 : 10);
    }
    /* Step cost for each output row */
    pNew->rRun = sqlite3LogEstAdd(pNew->rRun, pNew->nOut);
    whereLoopOutputAdjust(pBuilder->pWC, pNew, pSrc->iCursor);
    rc = whereLoopInsert(pBuilder, pNew);
    if( (pNew->wsFlags & WHERE_TOP_LIMIT)==0
     && pNew->u.btree.nEq<(pProbe->nColumn + (pProbe->zName!=0))
    ){
      whereLoopAddBtreeIndex(pBuilder, pSrc, pProbe, nInMul+nIn);
    }
4534
4535
4536
4537
4538
4539
4540
4541
4542
4543
4544
4545
4546
4547
4548
4549
4550
4551
4552
4553
4554
        pNew->u.btree.pIndex = 0;
        pNew->nLTerm = 1;
        pNew->aLTerm[0] = pTerm;
        /* TUNING: One-time cost for computing the automatic index is
        ** approximately 7*N*log2(N) where N is the number of rows in
        ** the table being indexed. */
        pNew->rSetup = rLogSize + rSize + 28;  assert( 28==sqlite3LogEst(7) );
        pNew->rSetup += pTab->szTabRow;
        /* TUNING: Each index lookup yields 20 rows in the table.  This
        ** is more than the usual guess of 10 rows, since we have no way
        ** of knowning how selective the index will ultimately be.  It would
        ** not be unreasonable to make this value much larger. */
        pNew->nOut = 43;  assert( 43==sqlite3LogEst(20) );
        pNew->rRun = sqlite3LogEstAdd(rLogSize,pNew->nOut) + pTab->szTabRow;
        pNew->wsFlags = WHERE_AUTO_INDEX;
        pNew->prereq = mExtra | pTerm->prereqRight;
        rc = whereLoopInsert(pBuilder, pNew);
      }
    }
  }
#endif /* SQLITE_OMIT_AUTOMATIC_INDEX */







<





|







4528
4529
4530
4531
4532
4533
4534

4535
4536
4537
4538
4539
4540
4541
4542
4543
4544
4545
4546
4547
        pNew->u.btree.pIndex = 0;
        pNew->nLTerm = 1;
        pNew->aLTerm[0] = pTerm;
        /* TUNING: One-time cost for computing the automatic index is
        ** approximately 7*N*log2(N) where N is the number of rows in
        ** the table being indexed. */
        pNew->rSetup = rLogSize + rSize + 28;  assert( 28==sqlite3LogEst(7) );

        /* TUNING: Each index lookup yields 20 rows in the table.  This
        ** is more than the usual guess of 10 rows, since we have no way
        ** of knowning how selective the index will ultimately be.  It would
        ** not be unreasonable to make this value much larger. */
        pNew->nOut = 43;  assert( 43==sqlite3LogEst(20) );
        pNew->rRun = sqlite3LogEstAdd(rLogSize,pNew->nOut);
        pNew->wsFlags = WHERE_AUTO_INDEX;
        pNew->prereq = mExtra | pTerm->prereqRight;
        rc = whereLoopInsert(pBuilder, pNew);
      }
    }
  }
#endif /* SQLITE_OMIT_AUTOMATIC_INDEX */
4575
4576
4577
4578
4579
4580
4581
4582
4583
4584
4585
4586
4587
4588
4589
4590
4591
4592
4593
4594

4595
4596
4597
4598
4599
4600
4601
4602
4603
4604
4605
4606
4607

4608
4609
4610
4611
4612
4613
4614
4615
4616
4617
4618
4619
4620
4621
      pNew->wsFlags = WHERE_IPK;

      /* Full table scan */
      pNew->iSortIdx = b ? iSortIdx : 0;
      /* TUNING: Cost of full table scan is 3*(N + log2(N)).
      **  +  The extra 3 factor is to encourage the use of indexed lookups
      **     over full scans.  FIXME */
      pNew->rRun = sqlite3LogEstAdd(rSize,rLogSize) + 16 + pTab->szTabRow;
      whereLoopOutputAdjust(pWC, pNew, pSrc->iCursor);
      rc = whereLoopInsert(pBuilder, pNew);
      pNew->nOut = rSize;
      if( rc ) break;
    }else{
      Bitmask m = pSrc->colUsed & ~columnsInIndex(pProbe);
      pNew->wsFlags = (m==0) ? (WHERE_IDX_ONLY|WHERE_INDEXED) : WHERE_INDEXED;

      /* Full scan via index */
      if( b
       || ( m==0
         && pProbe->bUnordered==0

         && (pWInfo->wctrlFlags & WHERE_ONEPASS_DESIRED)==0
         && sqlite3GlobalConfig.bUseCis
         && OptimizationEnabled(pWInfo->pParse->db, SQLITE_CoverIdxScan)
          )
      ){
        pNew->iSortIdx = b ? iSortIdx : 0;
        if( m==0 ){
          /* TUNING: Cost of a covering index scan is K*(N + log2(N)).
          **  +  The extra factor K of between 1.1 (iScanRatio between 0
          **     and 9) and 2.8 (iScanRatio between 126 and 127) is added
          **     to encourage the use of indexed lookups.  FIXME
          */
          pNew->rRun = sqlite3LogEstAdd(rSize,rLogSize) + 10;

        }else{
          assert( b!=0 ); 
          /* TUNING: Cost of scanning a non-covering index is (N+1)*log2(N)
          ** which we will simplify to just N*log2(N) */
          pNew->rRun = rSize + rLogSize;
        }
        pNew->rRun += pProbe->szIdxRow;
        whereLoopOutputAdjust(pWC, pNew, pSrc->iCursor);
        rc = whereLoopInsert(pBuilder, pNew);
        pNew->nOut = rSize;
        if( rc ) break;
      }
    }








|












>








|
|
|

|
>






<







4568
4569
4570
4571
4572
4573
4574
4575
4576
4577
4578
4579
4580
4581
4582
4583
4584
4585
4586
4587
4588
4589
4590
4591
4592
4593
4594
4595
4596
4597
4598
4599
4600
4601
4602
4603
4604
4605
4606
4607
4608

4609
4610
4611
4612
4613
4614
4615
      pNew->wsFlags = WHERE_IPK;

      /* Full table scan */
      pNew->iSortIdx = b ? iSortIdx : 0;
      /* TUNING: Cost of full table scan is 3*(N + log2(N)).
      **  +  The extra 3 factor is to encourage the use of indexed lookups
      **     over full scans.  FIXME */
      pNew->rRun = sqlite3LogEstAdd(rSize,rLogSize) + 16;
      whereLoopOutputAdjust(pWC, pNew, pSrc->iCursor);
      rc = whereLoopInsert(pBuilder, pNew);
      pNew->nOut = rSize;
      if( rc ) break;
    }else{
      Bitmask m = pSrc->colUsed & ~columnsInIndex(pProbe);
      pNew->wsFlags = (m==0) ? (WHERE_IDX_ONLY|WHERE_INDEXED) : WHERE_INDEXED;

      /* Full scan via index */
      if( b
       || ( m==0
         && pProbe->bUnordered==0
         && pProbe->szIdxRow<pTab->szTabRow
         && (pWInfo->wctrlFlags & WHERE_ONEPASS_DESIRED)==0
         && sqlite3GlobalConfig.bUseCis
         && OptimizationEnabled(pWInfo->pParse->db, SQLITE_CoverIdxScan)
          )
      ){
        pNew->iSortIdx = b ? iSortIdx : 0;
        if( m==0 ){
          /* TUNING: Cost of a covering index scan is K*(N + log2(N)).
          **  +  The extra factor K of between 1.1 and 3.0 that depends
          **     on the relative sizes of the table and the index.  K
          **     is smaller for smaller indices, thus favoring them.
          */
          pNew->rRun = sqlite3LogEstAdd(rSize,rLogSize) + 1 +
                        (15*pProbe->szIdxRow)/pTab->szTabRow;
        }else{
          assert( b!=0 ); 
          /* TUNING: Cost of scanning a non-covering index is (N+1)*log2(N)
          ** which we will simplify to just N*log2(N) */
          pNew->rRun = rSize + rLogSize;
        }

        whereLoopOutputAdjust(pWC, pNew, pSrc->iCursor);
        rc = whereLoopInsert(pBuilder, pNew);
        pNew->nOut = rSize;
        if( rc ) break;
      }
    }

4779
4780
4781
4782
4783
4784
4785
4786
4787
4788
4789
4790
4791
4792
4793
      pNew->u.vtab.idxNum = pIdxInfo->idxNum;
      pNew->u.vtab.needFree = pIdxInfo->needToFreeIdxStr;
      pIdxInfo->needToFreeIdxStr = 0;
      pNew->u.vtab.idxStr = pIdxInfo->idxStr;
      pNew->u.vtab.isOrdered = (u8)((pIdxInfo->nOrderBy!=0)
                                     && pIdxInfo->orderByConsumed);
      pNew->rSetup = 0;
      pNew->rRun = sqlite3LogEstFromDouble(pIdxInfo->estimatedCost) + 55;
      /* TUNING: Every virtual table query returns 25 rows */
      pNew->nOut = 46;  assert( 46==sqlite3LogEst(25) );
      whereLoopInsert(pBuilder, pNew);
      if( pNew->u.vtab.needFree ){
        sqlite3_free(pNew->u.vtab.idxStr);
        pNew->u.vtab.needFree = 0;
      }







|







4773
4774
4775
4776
4777
4778
4779
4780
4781
4782
4783
4784
4785
4786
4787
      pNew->u.vtab.idxNum = pIdxInfo->idxNum;
      pNew->u.vtab.needFree = pIdxInfo->needToFreeIdxStr;
      pIdxInfo->needToFreeIdxStr = 0;
      pNew->u.vtab.idxStr = pIdxInfo->idxStr;
      pNew->u.vtab.isOrdered = (u8)((pIdxInfo->nOrderBy!=0)
                                     && pIdxInfo->orderByConsumed);
      pNew->rSetup = 0;
      pNew->rRun = sqlite3LogEstFromDouble(pIdxInfo->estimatedCost);
      /* TUNING: Every virtual table query returns 25 rows */
      pNew->nOut = 46;  assert( 46==sqlite3LogEst(25) );
      whereLoopInsert(pBuilder, pNew);
      if( pNew->u.vtab.needFree ){
        sqlite3_free(pNew->u.vtab.idxStr);
        pNew->u.vtab.needFree = 0;
      }
5272
5273
5274
5275
5276
5277
5278
5279
5280
5281
5282
5283
5284
5285
5286
  if( pWInfo->pOrderBy==0 || nRowEst==0 ){
    aFrom[0].isOrderedValid = 1;
  }else{
    /* TUNING: Estimated cost of sorting is 48*N*log2(N) where N is the
    ** number of output rows. The 48 is the expected size of a row to sort. 
    ** FIXME:  compute a better estimate of the 48 multiplier based on the
    ** result set expressions. */
    rSortCost = nRowEst + estLog(nRowEst) + 55;
    WHERETRACE(0x002,("---- sort cost=%-3d\n", rSortCost));
  }

  /* Compute successively longer WherePaths using the previous generation
  ** of WherePaths as the basis for the next.  Keep track of the mxChoice
  ** best paths at each generation */
  for(iLoop=0; iLoop<nLoop; iLoop++){







|







5266
5267
5268
5269
5270
5271
5272
5273
5274
5275
5276
5277
5278
5279
5280
  if( pWInfo->pOrderBy==0 || nRowEst==0 ){
    aFrom[0].isOrderedValid = 1;
  }else{
    /* TUNING: Estimated cost of sorting is 48*N*log2(N) where N is the
    ** number of output rows. The 48 is the expected size of a row to sort. 
    ** FIXME:  compute a better estimate of the 48 multiplier based on the
    ** result set expressions. */
    rSortCost = nRowEst + estLog(nRowEst);
    WHERETRACE(0x002,("---- sort cost=%-3d\n", rSortCost));
  }

  /* Compute successively longer WherePaths using the previous generation
  ** of WherePaths as the basis for the next.  Keep track of the mxChoice
  ** best paths at each generation */
  for(iLoop=0; iLoop<nLoop; iLoop++){
Changes to test/select1.test.
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
     SELECT * FROM test1 a, test1 b LIMIT 1
  }
} {a.f1 11 a.f2 22 b.f1 11 b.f2 22}
do_test select1-6.9.7 {
  set x [execsql2 {
     SELECT * FROM test1 a, (select 5, 6) LIMIT 1
  }]
  regsub -all {subquery_[0-9a-fA-F]+_} $x {subquery} x
  set x
} {a.f1 11 a.f2 22 sqlite_subquery.5 5 sqlite_subquery.6 6}
do_test select1-6.9.8 {
  set x [execsql2 {
     SELECT * FROM test1 a, (select 5 AS x, 6 AS y) AS b LIMIT 1
  }]
  regsub -all {subquery_[0-9a-fA-F]+_} $x {subquery} x







|







538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
     SELECT * FROM test1 a, test1 b LIMIT 1
  }
} {a.f1 11 a.f2 22 b.f1 11 b.f2 22}
do_test select1-6.9.7 {
  set x [execsql2 {
     SELECT * FROM test1 a, (select 5, 6) LIMIT 1
  }]
  regsub -all {sq_[0-9a-fA-F_]+} $x {subquery} x
  set x
} {a.f1 11 a.f2 22 sqlite_subquery.5 5 sqlite_subquery.6 6}
do_test select1-6.9.8 {
  set x [execsql2 {
     SELECT * FROM test1 a, (select 5 AS x, 6 AS y) AS b LIMIT 1
  }]
  regsub -all {subquery_[0-9a-fA-F]+_} $x {subquery} x
Changes to test/where9.test.
777
778
779
780
781
782
783











784









785
786
787
788
789
790
791
  catchsql {
    UPDATE t1 INDEXED BY t1b SET a=a+100
     WHERE (+b IS NULL AND c NOT NULL AND d NOT NULL)
        OR (b NOT NULL AND c IS NULL AND d NOT NULL)
        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
  }
} {1 {no query solution}}











if {1} {









  do_test where9-6.8.3 {
    catchsql {
      UPDATE t1 INDEXED BY t1b SET a=a+100
       WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
          OR (b NOT NULL AND c IS NULL AND d NOT NULL)
          OR (b NOT NULL AND c NOT NULL AND d IS NULL)
    }







>
>
>
>
>
>
>
>
>
>
>
|
>
>
>
>
>
>
>
>
>







777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
  catchsql {
    UPDATE t1 INDEXED BY t1b SET a=a+100
     WHERE (+b IS NULL AND c NOT NULL AND d NOT NULL)
        OR (b NOT NULL AND c IS NULL AND d NOT NULL)
        OR (b NOT NULL AND c NOT NULL AND d IS NULL)
  }
} {1 {no query solution}}
ifcapable stat4||stat3 {
  # When STAT3 is enabled, the "b NOT NULL" terms get translated
  # into b>NULL, which can be satified by the index t1b.  It is a very
  # expensive way to do the query, but it works, and so a solution is possible.
  do_test where9-6.8.3-stat4 {
    catchsql {
      UPDATE t1 INDEXED BY t1b SET a=a+100
       WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
          OR (b NOT NULL AND c IS NULL AND d NOT NULL)
          OR (b NOT NULL AND c NOT NULL AND d IS NULL)
    }
  } {0 {}}
  do_test where9-6.8.4-stat4 {
    catchsql {
      DELETE FROM t1 INDEXED BY t1b
       WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
          OR (b NOT NULL AND c IS NULL AND d NOT NULL)
          OR (b NOT NULL AND c NOT NULL AND d IS NULL)
    }
  } {0 {}}
} else {
  do_test where9-6.8.3 {
    catchsql {
      UPDATE t1 INDEXED BY t1b SET a=a+100
       WHERE (b IS NULL AND c NOT NULL AND d NOT NULL)
          OR (b NOT NULL AND c IS NULL AND d NOT NULL)
          OR (b NOT NULL AND c NOT NULL AND d IS NULL)
    }