Many hyperlinks are disabled.
Use anonymous login
to enable hyperlinks.
Overview
Comment: | Changes to the query planner that improve the order in which tables/indexes are scanned in join queries. |
---|---|
Downloads: | Tarball | ZIP archive |
Timelines: | family | ancestors | descendants | both | trunk |
Files: | files | file ages | folders |
SHA1: |
19f799b32f9d1be25d4185ce18b13f4d |
User & Date: | dan 2009-08-13 07:09:33.000 |
References
2009-12-16
| ||
16:52 | • Ticket [31338dca7e] OR operator in WHERE clause gives wrong answer when indexed status still Open with 1 other change (artifact: c9fd070a32 user: drh) | |
Context
2009-08-13
| ||
15:42 | Merge the accidental fork. (check-in: 86a06dd049 user: drh tags: trunk) | |
07:09 | Changes to the query planner that improve the order in which tables/indexes are scanned in join queries. (check-in: 19f799b32f user: dan tags: trunk) | |
2009-08-12
| ||
15:34 | Fixed some compiler warnings in WINCE only sections when using the MSVC compiler. (check-in: 1f0a93e17d user: shane tags: trunk) | |
Changes
Changes to src/where.c.
︙ | ︙ | |||
191 192 193 194 195 196 197 198 199 200 201 202 203 204 | ** A WhereCost object records a lookup strategy and the estimated ** cost of pursuing that strategy. */ struct WhereCost { WherePlan plan; /* The lookup strategy */ double rCost; /* Overall cost of pursuing this search strategy */ double nRow; /* Estimated number of output rows */ }; /* ** Bitmasks for the operators that indices are able to exploit. An ** OR-ed combination of these values can be used when searching for ** terms in the where clause. */ | > | 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 | ** A WhereCost object records a lookup strategy and the estimated ** cost of pursuing that strategy. */ struct WhereCost { WherePlan plan; /* The lookup strategy */ double rCost; /* Overall cost of pursuing this search strategy */ double nRow; /* Estimated number of output rows */ Bitmask used; /* Bitmask of cursors used by this plan */ }; /* ** Bitmasks for the operators that indices are able to exploit. An ** OR-ed combination of these values can be used when searching for ** terms in the where clause. */ |
︙ | ︙ | |||
1334 1335 1336 1337 1338 1339 1340 1341 1342 1343 1344 1345 1346 1347 | struct ExprList_item *pTerm; /* A term of the ORDER BY clause */ sqlite3 *db = pParse->db; assert( pOrderBy!=0 ); nTerm = pOrderBy->nExpr; assert( nTerm>0 ); /* Match terms of the ORDER BY clause against columns of ** the index. ** ** Note that indices have pIdx->nColumn regular columns plus ** one additional column containing the rowid. The rowid column ** of the index is also allowed to match against the ORDER BY ** clause. | > > > > > | 1335 1336 1337 1338 1339 1340 1341 1342 1343 1344 1345 1346 1347 1348 1349 1350 1351 1352 1353 | struct ExprList_item *pTerm; /* A term of the ORDER BY clause */ sqlite3 *db = pParse->db; assert( pOrderBy!=0 ); nTerm = pOrderBy->nExpr; assert( nTerm>0 ); /* Argument pIdx must either point to a 'real' named index structure, ** or an index structure allocated on the stack by bestBtreeIndex() to ** represent the rowid index that is part of every table. */ assert( pIdx->zName || (pIdx->nColumn==1 && pIdx->aiColumn[0]==-1) ); /* Match terms of the ORDER BY clause against columns of ** the index. ** ** Note that indices have pIdx->nColumn regular columns plus ** one additional column containing the rowid. The rowid column ** of the index is also allowed to match against the ORDER BY ** clause. |
︙ | ︙ | |||
1360 1361 1362 1363 1364 1365 1366 | ** left-most table of the FROM clause */ break; } pColl = sqlite3ExprCollSeq(pParse, pExpr); if( !pColl ){ pColl = db->pDfltColl; } | | | 1366 1367 1368 1369 1370 1371 1372 1373 1374 1375 1376 1377 1378 1379 1380 | ** left-most table of the FROM clause */ break; } pColl = sqlite3ExprCollSeq(pParse, pExpr); if( !pColl ){ pColl = db->pDfltColl; } if( pIdx->zName && i<pIdx->nColumn ){ iColumn = pIdx->aiColumn[i]; if( iColumn==pIdx->pTable->iPKey ){ iColumn = -1; } iSortOrder = pIdx->aSortOrder[i]; zColl = pIdx->azColl[i]; }else{ |
︙ | ︙ | |||
1389 1390 1391 1392 1393 1394 1395 | }else{ /* If an index column fails to match and is not constrained by == ** then the index cannot satisfy the ORDER BY constraint. */ return 0; } } | | | 1395 1396 1397 1398 1399 1400 1401 1402 1403 1404 1405 1406 1407 1408 1409 | }else{ /* If an index column fails to match and is not constrained by == ** then the index cannot satisfy the ORDER BY constraint. */ return 0; } } assert( pIdx->aSortOrder!=0 || iColumn==-1 ); assert( pTerm->sortOrder==0 || pTerm->sortOrder==1 ); assert( iSortOrder==0 || iSortOrder==1 ); termSortOrder = iSortOrder ^ pTerm->sortOrder; if( i>nEqCol ){ if( termSortOrder!=sortOrder ){ /* Indices can only be used if all ORDER BY terms past the ** equality constraints are all either DESC or ASC. */ |
︙ | ︙ | |||
1429 1430 1431 1432 1433 1434 1435 | && !referencesOtherTables(pOrderBy, pMaskSet, j, base) ){ /* All terms of this index match some prefix of the ORDER BY clause ** and the index is UNIQUE and no terms on the tail of the ORDER BY ** clause reference other tables in a join. If this is all true then ** the order by clause is superfluous. */ return 1; } | < < < < < < < < < < < < < < < < < < < < < < < < | 1435 1436 1437 1438 1439 1440 1441 1442 1443 1444 1445 1446 1447 1448 | && !referencesOtherTables(pOrderBy, pMaskSet, j, base) ){ /* All terms of this index match some prefix of the ORDER BY clause ** and the index is UNIQUE and no terms on the tail of the ORDER BY ** clause reference other tables in a join. If this is all true then ** the order by clause is superfluous. */ return 1; } return 0; } /* ** Prepare a crude estimate of the logarithm of the input value. ** The results need not be exact. This is only used for estimating ** the total cost of performing operations with O(logN) or O(NlogN) |
︙ | ︙ | |||
1556 1557 1558 1559 1560 1561 1562 1563 1564 1565 1566 1567 1568 1569 | ){ WhereClause * const pOrWC = &pTerm->u.pOrInfo->wc; WhereTerm * const pOrWCEnd = &pOrWC->a[pOrWC->nTerm]; WhereTerm *pOrTerm; int flags = WHERE_MULTI_OR; double rTotal = 0; double nRow = 0; for(pOrTerm=pOrWC->a; pOrTerm<pOrWCEnd; pOrTerm++){ WhereCost sTermCost; WHERETRACE(("... Multi-index OR testing for term %d of %d....\n", (pOrTerm - pOrWC->a), (pTerm - pWC->a) )); if( pOrTerm->eOperator==WO_AND ){ | > | 1538 1539 1540 1541 1542 1543 1544 1545 1546 1547 1548 1549 1550 1551 1552 | ){ WhereClause * const pOrWC = &pTerm->u.pOrInfo->wc; WhereTerm * const pOrWCEnd = &pOrWC->a[pOrWC->nTerm]; WhereTerm *pOrTerm; int flags = WHERE_MULTI_OR; double rTotal = 0; double nRow = 0; Bitmask used = 0; for(pOrTerm=pOrWC->a; pOrTerm<pOrWCEnd; pOrTerm++){ WhereCost sTermCost; WHERETRACE(("... Multi-index OR testing for term %d of %d....\n", (pOrTerm - pOrWC->a), (pTerm - pWC->a) )); if( pOrTerm->eOperator==WO_AND ){ |
︙ | ︙ | |||
1578 1579 1580 1581 1582 1583 1584 1585 1586 1587 1588 1589 1590 1591 1592 1593 1594 1595 1596 1597 1598 1599 1600 1601 1602 1603 1604 1605 1606 1607 1608 | tempWC.nTerm = 1; bestIndex(pParse, &tempWC, pSrc, notReady, 0, &sTermCost); }else{ continue; } rTotal += sTermCost.rCost; nRow += sTermCost.nRow; if( rTotal>=pCost->rCost ) break; } /* If there is an ORDER BY clause, increase the scan cost to account ** for the cost of the sort. */ if( pOrderBy!=0 ){ rTotal += nRow*estLog(nRow); WHERETRACE(("... sorting increases OR cost to %.9g\n", rTotal)); } /* If the cost of scanning using this OR term for optimization is ** less than the current cost stored in pCost, replace the contents ** of pCost. */ WHERETRACE(("... multi-index OR cost=%.9g nrow=%.9g\n", rTotal, nRow)); if( rTotal<pCost->rCost ){ pCost->rCost = rTotal; pCost->nRow = nRow; pCost->plan.wsFlags = flags; pCost->plan.u.pTerm = pTerm; } } } #endif /* SQLITE_OMIT_OR_OPTIMIZATION */ } | > > | 1561 1562 1563 1564 1565 1566 1567 1568 1569 1570 1571 1572 1573 1574 1575 1576 1577 1578 1579 1580 1581 1582 1583 1584 1585 1586 1587 1588 1589 1590 1591 1592 1593 | tempWC.nTerm = 1; bestIndex(pParse, &tempWC, pSrc, notReady, 0, &sTermCost); }else{ continue; } rTotal += sTermCost.rCost; nRow += sTermCost.nRow; used |= sTermCost.used; if( rTotal>=pCost->rCost ) break; } /* If there is an ORDER BY clause, increase the scan cost to account ** for the cost of the sort. */ if( pOrderBy!=0 ){ rTotal += nRow*estLog(nRow); WHERETRACE(("... sorting increases OR cost to %.9g\n", rTotal)); } /* If the cost of scanning using this OR term for optimization is ** less than the current cost stored in pCost, replace the contents ** of pCost. */ WHERETRACE(("... multi-index OR cost=%.9g nrow=%.9g\n", rTotal, nRow)); if( rTotal<pCost->rCost ){ pCost->rCost = rTotal; pCost->nRow = nRow; pCost->used = used; pCost->plan.wsFlags = flags; pCost->plan.u.pTerm = pTerm; } } } #endif /* SQLITE_OMIT_OR_OPTIMIZATION */ } |
︙ | ︙ | |||
1847 1848 1849 1850 1851 1852 1853 | ** each time. */ pIdxCons = *(struct sqlite3_index_constraint**)&pIdxInfo->aConstraint; pUsage = pIdxInfo->aConstraintUsage; for(i=0; i<pIdxInfo->nConstraint; i++, pIdxCons++){ j = pIdxCons->iTermOffset; pTerm = &pWC->a[j]; | | > > > > > > > | 1832 1833 1834 1835 1836 1837 1838 1839 1840 1841 1842 1843 1844 1845 1846 1847 1848 1849 1850 1851 1852 1853 1854 1855 1856 1857 1858 1859 1860 1861 1862 1863 1864 1865 1866 1867 1868 1869 1870 1871 1872 | ** each time. */ pIdxCons = *(struct sqlite3_index_constraint**)&pIdxInfo->aConstraint; pUsage = pIdxInfo->aConstraintUsage; for(i=0; i<pIdxInfo->nConstraint; i++, pIdxCons++){ j = pIdxCons->iTermOffset; pTerm = &pWC->a[j]; pIdxCons->usable = (pTerm->prereqRight¬Ready) ? 0 : 1; } memset(pUsage, 0, sizeof(pUsage[0])*pIdxInfo->nConstraint); if( pIdxInfo->needToFreeIdxStr ){ sqlite3_free(pIdxInfo->idxStr); } pIdxInfo->idxStr = 0; pIdxInfo->idxNum = 0; pIdxInfo->needToFreeIdxStr = 0; pIdxInfo->orderByConsumed = 0; /* ((double)2) In case of SQLITE_OMIT_FLOATING_POINT... */ pIdxInfo->estimatedCost = SQLITE_BIG_DBL / ((double)2); nOrderBy = pIdxInfo->nOrderBy; if( !pOrderBy ){ pIdxInfo->nOrderBy = 0; } if( vtabBestIndex(pParse, pTab, pIdxInfo) ){ return; } pIdxCons = *(struct sqlite3_index_constraint**)&pIdxInfo->aConstraint; for(i=0; i<pIdxInfo->nConstraint; i++){ if( pUsage[i].argvIndex>0 ){ pCost->used |= pWC->a[pIdxCons[i].iTermOffset].prereqRight; } } /* The cost is not allowed to be larger than SQLITE_BIG_DBL (the ** inital value of lowestCost in this loop. If it is, then the ** (cost<lowestCost) test below will never be true. ** ** Use "(double)2" instead of "2.0" in case OMIT_FLOATING_POINT ** is defined. |
︙ | ︙ | |||
1930 1931 1932 1933 1934 1935 1936 | Parse *pParse, /* The parsing context */ WhereClause *pWC, /* The WHERE clause */ struct SrcList_item *pSrc, /* The FROM clause term to search */ Bitmask notReady, /* Mask of cursors that are not available */ ExprList *pOrderBy, /* The ORDER BY clause */ WhereCost *pCost /* Lowest cost query plan */ ){ | < < | | | < < < < | | | > | < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < | | | < < | > > > > > > > > > > > > | > > > | > > > > > > | | > > > > > > > < > > > > > > > > > | | | | < | > | | > > > > > > > > > > | > > > > > > > > > > > > > > > > > > > > > > > > > > | > > > > > > | > | | | | | | > | < | < | | > | > > > > > | < > > | > > > > | < < < < < < < < < > > | < < < < < < < < < < < < < < | < < | < < < | < | < | < < < < < < < < | | < > > > | | | > > > > | > > > > > > > > > > | > > > > > > > > | > > > > > > > | > | > > > > > > | | > | < | > > > > > > > > > > > > > | < > > | > > > | | > | > | | 1922 1923 1924 1925 1926 1927 1928 1929 1930 1931 1932 1933 1934 1935 1936 1937 1938 1939 1940 1941 1942 1943 1944 1945 1946 1947 1948 1949 1950 1951 1952 1953 1954 1955 1956 1957 1958 1959 1960 1961 1962 1963 1964 1965 1966 1967 1968 1969 1970 1971 1972 1973 1974 1975 1976 1977 1978 1979 1980 1981 1982 1983 1984 1985 1986 1987 1988 1989 1990 1991 1992 1993 1994 1995 1996 1997 1998 1999 2000 2001 2002 2003 2004 2005 2006 2007 2008 2009 2010 2011 2012 2013 2014 2015 2016 2017 2018 2019 2020 2021 2022 2023 2024 2025 2026 2027 2028 2029 2030 2031 2032 2033 2034 2035 2036 2037 2038 2039 2040 2041 2042 2043 2044 2045 2046 2047 2048 2049 2050 2051 2052 2053 2054 2055 2056 2057 2058 2059 2060 2061 2062 2063 2064 2065 2066 2067 2068 2069 2070 2071 2072 2073 2074 2075 2076 2077 2078 2079 2080 2081 2082 2083 2084 2085 2086 2087 2088 2089 2090 2091 2092 2093 2094 2095 2096 2097 2098 2099 2100 2101 2102 2103 2104 2105 2106 2107 2108 2109 2110 2111 2112 2113 2114 2115 2116 2117 2118 2119 2120 2121 2122 2123 2124 2125 2126 2127 2128 2129 2130 2131 2132 2133 2134 2135 2136 2137 2138 2139 2140 2141 2142 2143 2144 2145 2146 2147 2148 2149 2150 2151 2152 2153 2154 2155 2156 2157 2158 2159 2160 2161 2162 2163 2164 2165 2166 2167 2168 2169 2170 2171 2172 2173 2174 2175 2176 2177 2178 2179 2180 2181 2182 2183 2184 2185 2186 2187 2188 2189 2190 2191 2192 2193 2194 2195 2196 2197 2198 2199 2200 2201 2202 2203 2204 2205 2206 2207 2208 2209 2210 2211 2212 2213 2214 | Parse *pParse, /* The parsing context */ WhereClause *pWC, /* The WHERE clause */ struct SrcList_item *pSrc, /* The FROM clause term to search */ Bitmask notReady, /* Mask of cursors that are not available */ ExprList *pOrderBy, /* The ORDER BY clause */ WhereCost *pCost /* Lowest cost query plan */ ){ int iCur = pSrc->iCursor; /* The cursor of the table to be accessed */ Index *pProbe; /* An index we are evaluating */ Index *pIdx; /* Copy of pProbe, or zero for IPK index */ int eqTermMask; /* Current mask of valid equality operators */ int idxEqTermMask; /* Index mask of valid equality operators */ Index pk; unsigned int pkint[2] = {1000000, 1}; int pkicol = -1; int wsFlagMask; memset(pCost, 0, sizeof(*pCost)); pCost->rCost = SQLITE_BIG_DBL; /* If the pSrc table is the right table of a LEFT JOIN then we may not ** use an index to satisfy IS NULL constraints on that table. This is ** because columns might end up being NULL if the table does not match - ** a circumstance which the index cannot help us discover. Ticket #2177. */ if( pSrc->jointype & JT_LEFT ){ idxEqTermMask = WO_EQ|WO_IN; }else{ idxEqTermMask = WO_EQ|WO_IN|WO_ISNULL; } if( pSrc->pIndex ){ pIdx = pProbe = pSrc->pIndex; wsFlagMask = ~(WHERE_ROWID_EQ|WHERE_ROWID_RANGE); eqTermMask = idxEqTermMask; }else{ Index *pFirst = pSrc->pTab->pIndex; memset(&pk, 0, sizeof(Index)); pk.nColumn = 1; pk.aiColumn = &pkicol; pk.aiRowEst = pkint; pk.onError = OE_Replace; pk.pTable = pSrc->pTab; if( pSrc->notIndexed==0 ){ pk.pNext = pFirst; } if( pFirst && pFirst->aiRowEst ){ pkint[0] = pFirst->aiRowEst[0]; } pProbe = &pk; wsFlagMask = ~( WHERE_COLUMN_IN|WHERE_COLUMN_EQ|WHERE_COLUMN_NULL|WHERE_COLUMN_RANGE ); eqTermMask = WO_EQ|WO_IN; pIdx = 0; } for(; pProbe; pIdx=pProbe=pProbe->pNext){ const unsigned int * const aiRowEst = pProbe->aiRowEst; double cost; /* Cost of using pProbe */ double nRow; /* Estimated number of rows in result set */ int rev; /* True to scan in reverse order */ int wsFlags = 0; Bitmask used = 0; /* The following variables are populated based on the properties of ** scan being evaluated. They are then used to determine the expected ** cost and number of rows returned. ** ** nEq: ** Number of equality terms that can be implemented using the index. ** ** nInMul: ** The "in-multiplier". This is an estimate of how many seek operations ** SQLite must perform on the index in question. For example, if the ** WHERE clause is: ** ** WHERE a IN (1, 2, 3) AND b IN (4, 5, 6) ** ** SQLite must perform 9 lookups on an index on (a, b), so nInMul is ** set to 9. Given the same schema and either of the following WHERE ** clauses: ** ** WHERE a = 1 ** WHERE a >= 2 ** ** nInMul is set to 1. ** ** If there exists a WHERE term of the form "x IN (SELECT ...)", then ** the sub-select is assumed to return 25 rows for the purposes of ** determining nInMul. ** ** bInEst: ** Set to true if there was at least one "x IN (SELECT ...)" term used ** in determining the value of nInMul. ** ** nBound: ** Set based on whether or not there is a range constraint on the ** (nEq+1)th column of the index. 1 if there is neither an upper or ** lower bound, 3 if there is an upper or lower bound, or 9 if there ** is both an upper and lower bound. ** ** bSort: ** Boolean. True if there is an ORDER BY clause that will require an ** external sort (i.e. scanning the index being evaluated will not ** correctly order records). ** ** bLookup: ** Boolean. True if for each index entry visited a lookup on the ** corresponding table b-tree is required. This is always false ** for the rowid index. For other indexes, it is true unless all the ** columns of the table used by the SELECT statement are present in ** the index (such an index is sometimes described as a covering index). ** For example, given the index on (a, b), the second of the following ** two queries requires table b-tree lookups, but the first does not. ** ** SELECT a, b FROM tbl WHERE a = 1; ** SELECT a, b, c FROM tbl WHERE a = 1; */ int nEq; int bInEst = 0; int nInMul = 1; int nBound = 1; int bSort = 0; int bLookup = 0; /* Determine the values of nEq and nInMul */ for(nEq=0; nEq<pProbe->nColumn; nEq++){ WhereTerm *pTerm; /* A single term of the WHERE clause */ int j = pProbe->aiColumn[nEq]; pTerm = findTerm(pWC, iCur, j, notReady, eqTermMask, pIdx); if( pTerm==0 ) break; wsFlags |= (WHERE_COLUMN_EQ|WHERE_ROWID_EQ); if( pTerm->eOperator & WO_IN ){ Expr *pExpr = pTerm->pExpr; wsFlags |= WHERE_COLUMN_IN; if( ExprHasProperty(pExpr, EP_xIsSelect) ){ nInMul *= 25; bInEst = 1; }else if( pExpr->x.pList ){ nInMul *= pExpr->x.pList->nExpr + 1; } }else if( pTerm->eOperator & WO_ISNULL ){ wsFlags |= WHERE_COLUMN_NULL; } used |= pTerm->prereqRight; } /* Determine the value of nBound. */ if( nEq<pProbe->nColumn ){ int j = pProbe->aiColumn[nEq]; if( findTerm(pWC, iCur, j, notReady, WO_LT|WO_LE|WO_GT|WO_GE, pIdx) ){ WhereTerm *pTop = findTerm(pWC, iCur, j, notReady, WO_LT|WO_LE, pIdx); WhereTerm *pBtm = findTerm(pWC, iCur, j, notReady, WO_GT|WO_GE, pIdx); if( pTop ){ wsFlags |= WHERE_TOP_LIMIT; nBound *= 3; used |= pTop->prereqRight; } if( pBtm ){ wsFlags |= WHERE_BTM_LIMIT; nBound *= 3; used |= pBtm->prereqRight; } wsFlags |= (WHERE_COLUMN_RANGE|WHERE_ROWID_RANGE); } }else if( pProbe->onError!=OE_None ){ testcase( wsFlags & WHERE_COLUMN_IN ); testcase( wsFlags & WHERE_COLUMN_NULL ); if( (wsFlags & (WHERE_COLUMN_IN|WHERE_COLUMN_NULL))==0 ){ wsFlags |= WHERE_UNIQUE; } } /* If there is an ORDER BY clause and the index being considered will ** naturally scan rows in the required order, set the appropriate flags ** in wsFlags. Otherwise, if there is an ORDER BY clause but the index ** will scan rows in a different order, set the bSort variable. */ if( pOrderBy ){ if( (wsFlags & (WHERE_COLUMN_IN|WHERE_COLUMN_NULL))==0 && isSortingIndex(pParse,pWC->pMaskSet,pProbe,iCur,pOrderBy,nEq,&rev) ){ wsFlags |= WHERE_ROWID_RANGE|WHERE_COLUMN_RANGE|WHERE_ORDERBY; wsFlags |= (rev ? WHERE_REVERSE : 0); }else{ bSort = 1; } } /* If currently calculating the cost of using an index (not the IPK ** index), determine if all required column data may be obtained without ** seeking to entries in the main table (i.e. if the index is a covering ** index for this query). If it is, set the WHERE_IDX_ONLY flag in ** wsFlags. Otherwise, set the bLookup variable to true. */ if( pIdx && wsFlags ){ Bitmask m = pSrc->colUsed; int j; for(j=0; j<pIdx->nColumn; j++){ int x = pIdx->aiColumn[j]; if( x<BMS-1 ){ m &= ~(((Bitmask)1)<<x); } } if( m==0 ){ wsFlags |= WHERE_IDX_ONLY; }else{ bLookup = 1; } } #if 0 if( bInEst && (nInMul*aiRowEst[nEq])>(aiRowEst[0]/2) ){ nInMul = aiRowEst[0] / (2 * aiRowEst[nEq]); } nRow = (double)(aiRowEst[nEq] * nInMul) / nBound; cost = (nEq>0) * nInMul * estLog(aiRowEst[0]) + nRow + bSort * nRow * estLog(nRow) + bLookup * nRow * estLog(aiRowEst[0]); #else /* The following block calculates nRow and cost for the index scan ** in the same way as SQLite versions 3.6.17 and earlier. Some elements ** of this calculation are difficult to justify. But using this strategy ** works well in practice and causes the test suite to pass. */ nRow = (double)(aiRowEst[nEq] * nInMul); if( bInEst && nRow*2>aiRowEst[0] ){ nRow = aiRowEst[0]/2; nInMul = nRow / aiRowEst[nEq]; } cost = nRow + nInMul*estLog(aiRowEst[0]); nRow /= nBound; cost /= nBound; if( bSort ){ cost += cost*estLog(cost); } if( pIdx && bLookup==0 ){ cost /= 2; } #endif WHERETRACE(( "tbl=%s idx=%s nEq=%d nInMul=%d nBound=%d bSort=%d bLookup=%d" " wsFlags=%d (nRow=%.2f cost=%.2f)\n", pSrc->pTab->zName, (pIdx ? pIdx->zName : "ipk"), nEq, nInMul, nBound, bSort, bLookup, wsFlags, nRow, cost )); if( (!pIdx || wsFlags) && cost<pCost->rCost ){ pCost->rCost = cost; pCost->nRow = nRow; pCost->used = used; pCost->plan.wsFlags = (wsFlags&wsFlagMask); pCost->plan.nEq = nEq; pCost->plan.u.pIdx = pIdx; } if( pSrc->pIndex ) break; wsFlagMask = ~(WHERE_ROWID_EQ|WHERE_ROWID_RANGE); eqTermMask = idxEqTermMask; } /* If there is no ORDER BY clause and the SQLITE_ReverseOrder flag ** is set, then reverse the order that the index will be scanned ** in. This is used for application testing, to help find cases ** where application behaviour depends on the (undefined) order that ** SQLite outputs rows in in the absence of an ORDER BY clause. */ if( !pOrderBy && pParse->db->flags & SQLITE_ReverseOrder ){ pCost->plan.wsFlags |= WHERE_REVERSE; } assert( pOrderBy || (pCost->plan.wsFlags&WHERE_ORDERBY)==0 ); assert( pCost->plan.u.pIdx==0 || (pCost->plan.wsFlags&WHERE_ROWID_EQ)==0 ); assert( pSrc->pIndex==0 || pCost->plan.u.pIdx==0 || pCost->plan.u.pIdx==pSrc->pIndex ); WHERETRACE(("best index is: %s\n", (pCost->plan.u.pIdx ? pCost->plan.u.pIdx->zName : "ipk") )); bestOrClauseIndex(pParse, pWC, pSrc, notReady, pOrderBy, pCost); pCost->plan.wsFlags |= eqTermMask; } /* ** Find the query plan for accessing table pSrc->pTab. Write the ** best query plan and its cost into the WhereCost object supplied ** as the last parameter. This function may calculate the cost of ** both real and virtual table scans. |
︙ | ︙ | |||
3267 3268 3269 3270 3271 3272 3273 | pLevel = pWInfo->a; andFlags = ~0; WHERETRACE(("*** Optimizer Start ***\n")); for(i=iFrom=0, pLevel=pWInfo->a; i<pTabList->nSrc; i++, pLevel++){ WhereCost bestPlan; /* Most efficient plan seen so far */ Index *pIdx; /* Index for FROM table at pTabItem */ int j; /* For looping over FROM tables */ | | | > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > | | | | | | | | | | | | | | | | | | | | | | > > > | < > | | | | | > | | 3254 3255 3256 3257 3258 3259 3260 3261 3262 3263 3264 3265 3266 3267 3268 3269 3270 3271 3272 3273 3274 3275 3276 3277 3278 3279 3280 3281 3282 3283 3284 3285 3286 3287 3288 3289 3290 3291 3292 3293 3294 3295 3296 3297 3298 3299 3300 3301 3302 3303 3304 3305 3306 3307 3308 3309 3310 3311 3312 3313 3314 3315 3316 3317 3318 3319 3320 3321 3322 3323 3324 3325 3326 3327 3328 3329 3330 3331 3332 3333 3334 3335 3336 3337 3338 3339 3340 3341 3342 3343 | pLevel = pWInfo->a; andFlags = ~0; WHERETRACE(("*** Optimizer Start ***\n")); for(i=iFrom=0, pLevel=pWInfo->a; i<pTabList->nSrc; i++, pLevel++){ WhereCost bestPlan; /* Most efficient plan seen so far */ Index *pIdx; /* Index for FROM table at pTabItem */ int j; /* For looping over FROM tables */ int bestJ = -1; /* The value of j */ Bitmask m; /* Bitmask value for j or bestJ */ int isOptimal; /* Iterator for optimal/non-optimal search */ memset(&bestPlan, 0, sizeof(bestPlan)); bestPlan.rCost = SQLITE_BIG_DBL; /* Loop through the remaining entries in the FROM clause to find the ** next nested loop. The FROM clause entries may be iterated through ** either once or twice. ** ** The first iteration, which is always performed, searches for the ** FROM clause entry that permits the lowest-cost, "optimal" scan. In ** this context an optimal scan is one that uses the same strategy ** for the given FROM clause entry as would be selected if the entry ** were used as the innermost nested loop. ** ** The second iteration is only performed if no optimal scan strategies ** were found by the first. This iteration is used to search for the ** lowest cost scan overall. ** ** Previous versions of SQLite performed only the second iteration - ** the next outermost loop was always that with the lowest overall ** cost. However, this meant that SQLite could select the wrong plan ** for scripts such as the following: ** ** CREATE TABLE t1(a, b); ** CREATE TABLE t2(c, d); ** SELECT * FROM t2, t1 WHERE t2.rowid = t1.a; ** ** The best strategy is to iterate through table t1 first. However it ** is not possible to determine this with a simple greedy algorithm. ** However, since the cost of a linear scan through table t2 is the same ** as the cost of a linear scan through table t1, a simple greedy ** algorithm may choose to use t2 for the outer loop, which is a much ** costlier approach. */ for(isOptimal=1; isOptimal>=0 && bestJ<0; isOptimal--){ Bitmask mask = (isOptimal ? 0 : notReady); assert( (pTabList->nSrc-iFrom)>1 || isOptimal ); for(j=iFrom, pTabItem=&pTabList->a[j]; j<pTabList->nSrc; j++, pTabItem++){ int doNotReorder; /* True if this table should not be reordered */ WhereCost sCost; /* Cost information from best[Virtual]Index() */ ExprList *pOrderBy; /* ORDER BY clause for index to optimize */ doNotReorder = (pTabItem->jointype & (JT_LEFT|JT_CROSS))!=0; if( j!=iFrom && doNotReorder ) break; m = getMask(pMaskSet, pTabItem->iCursor); if( (m & notReady)==0 ){ if( j==iFrom ) iFrom++; continue; } pOrderBy = ((i==0 && ppOrderBy )?*ppOrderBy:0); assert( pTabItem->pTab ); #ifndef SQLITE_OMIT_VIRTUALTABLE if( IsVirtual(pTabItem->pTab) ){ sqlite3_index_info **pp = &pWInfo->a[j].pIdxInfo; bestVirtualIndex(pParse, pWC, pTabItem, mask, pOrderBy, &sCost, pp); }else #endif { bestBtreeIndex(pParse, pWC, pTabItem, mask, pOrderBy, &sCost); } assert( isOptimal || (sCost.used¬Ready)==0 ); if( (sCost.used¬Ready)==0 && (j==iFrom || sCost.rCost<bestPlan.rCost) ){ bestPlan = sCost; bestJ = j; } if( doNotReorder ) break; } } assert( bestJ>=0 ); assert( notReady & getMask(pMaskSet, pTabList->a[bestJ].iCursor) ); WHERETRACE(("*** Optimizer selects table %d for loop %d\n", bestJ, pLevel-pWInfo->a)); if( (bestPlan.plan.wsFlags & WHERE_ORDERBY)!=0 ){ *ppOrderBy = 0; } andFlags &= bestPlan.plan.wsFlags; |
︙ | ︙ |
Changes to test/triggerA.test.
︙ | ︙ | |||
75 76 77 78 79 80 81 | } } {1 10 2 3 4 5 6 7 8 9 five four three} do_test triggerA-1.6 { db eval { CREATE VIEW v5 AS SELECT x, b FROM t1, t2 WHERE y=c; SELECT * FROM v5; } | | | 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 | } } {1 10 2 3 4 5 6 7 8 9 five four three} do_test triggerA-1.6 { db eval { CREATE VIEW v5 AS SELECT x, b FROM t1, t2 WHERE y=c; SELECT * FROM v5; } } {10 1003 9 904 8 805 7 705 6 603 5 504 4 404 3 305 2 203 1 103} # Create INSTEAD OF triggers on the views. Run UPDATE and DELETE statements # using those triggers. Verify correct operation. # do_test triggerA-2.1 { db eval { CREATE TABLE result2(a,b); |
︙ | ︙ |
Changes to test/vtab6.test.
︙ | ︙ | |||
488 489 490 491 492 493 494 495 496 497 498 499 500 501 | } } {1 2 3} do_test vtab6-11.2.0 { execsql { CREATE INDEX ab_i ON ab_r(b); } } {} unset ::echo_module_cost do_test vtab6-11.2.1 { execsql { | > | 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 | } } {1 2 3} do_test vtab6-11.2.0 { execsql { CREATE INDEX ab_i ON ab_r(b); CREATE INDEX bc_i ON bc_r(b); } } {} unset ::echo_module_cost do_test vtab6-11.2.1 { execsql { |
︙ | ︙ | |||
556 557 558 559 560 561 562 | set ::echo_module_ignore_usable 1 db cache flush do_test vtab6-11.4.1 { catchsql { SELECT a, b, c FROM ab NATURAL JOIN bc; } | | | 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 | set ::echo_module_ignore_usable 1 db cache flush do_test vtab6-11.4.1 { catchsql { SELECT a, b, c FROM ab NATURAL JOIN bc; } } {1 {table bc: xBestIndex returned an invalid plan}} do_test vtab6-11.4.2 { catchsql { SELECT a, b, c FROM bc NATURAL JOIN ab; } } {1 {table ab: xBestIndex returned an invalid plan}} unset ::echo_module_ignore_usable finish_test |
Changes to test/where8.test.
︙ | ︙ | |||
283 284 285 286 287 288 289 | do_test where8-3.15 { execsql_status { SELECT c FROM t1, t2 WHERE a BETWEEN 1 AND 2 OR a = ( SELECT sum(e IS NULL) FROM t2 AS inner WHERE t2.d>inner.d ) } | | | 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 | do_test where8-3.15 { execsql_status { SELECT c FROM t1, t2 WHERE a BETWEEN 1 AND 2 OR a = ( SELECT sum(e IS NULL) FROM t2 AS inner WHERE t2.d>inner.d ) } } {I II I II I II I II I II I II III I II III I II III I II III I II III 9 0} #----------------------------------------------------------------------- # The following tests - where8-4.* - verify that adding or removing # indexes does not change the results returned by various queries. # do_test where8-4.1 { execsql { |
︙ | ︙ |