Many hyperlinks are disabled.
Use anonymous login
to enable hyperlinks.
Overview
Comment: | Merge the EXPLAIN QUERY PLAN changes from experimental into trunk. |
---|---|
Downloads: | Tarball | ZIP archive |
Timelines: | family | ancestors | descendants | both | trunk |
Files: | files | file ages | folders |
SHA1: |
ce27bf38405ce805dad95ec22cbe68dd |
User & Date: | drh 2010-11-15 14:44:30.000 |
Context
2010-11-15
| ||
14:51 | Test some example code from documentation page eqp.html. (check-in: 547bc2c232 user: dan tags: trunk) | |
14:44 | Merge the EXPLAIN QUERY PLAN changes from experimental into trunk. (check-in: ce27bf3840 user: drh tags: trunk) | |
11:35 | Minor additions to vacuum.test. (check-in: a397ed1622 user: dan tags: trunk) | |
2010-11-13
| ||
16:42 | Change the EXPLAIN QUERY PLAN output to use "USING INDEX" instead of "BY INDEX", and to use "SEARCH" instead of "SCAN" for loops that are not full-table scans. (Closed-Leaf check-in: 6611b76b02 user: dan tags: experimental) | |
Changes
Changes to src/expr.c.
︙ | ︙ | |||
1595 1596 1597 1598 1599 1600 1601 1602 1603 1604 1605 1606 1607 1608 | */ if( !ExprHasAnyProperty(pExpr, EP_VarSelect) && !pParse->pTriggerTab ){ int mem = ++pParse->nMem; sqlite3VdbeAddOp1(v, OP_If, mem); testAddr = sqlite3VdbeAddOp2(v, OP_Integer, 1, mem); assert( testAddr>0 || pParse->db->mallocFailed ); } switch( pExpr->op ){ case TK_IN: { char affinity; /* Affinity of the LHS of the IN */ KeyInfo keyInfo; /* Keyinfo for the generated table */ int addr; /* Address of OP_OpenEphemeral instruction */ Expr *pLeft = pExpr->pLeft; /* the LHS of the IN operator */ | > > > > > > > > > > | 1595 1596 1597 1598 1599 1600 1601 1602 1603 1604 1605 1606 1607 1608 1609 1610 1611 1612 1613 1614 1615 1616 1617 1618 | */ if( !ExprHasAnyProperty(pExpr, EP_VarSelect) && !pParse->pTriggerTab ){ int mem = ++pParse->nMem; sqlite3VdbeAddOp1(v, OP_If, mem); testAddr = sqlite3VdbeAddOp2(v, OP_Integer, 1, mem); assert( testAddr>0 || pParse->db->mallocFailed ); } #ifndef SQLITE_OMIT_EXPLAIN if( pParse->explain==2 ){ char *zMsg = sqlite3MPrintf( pParse->db, "EXECUTE %s%s SUBQUERY %d", testAddr?"":"CORRELATED ", pExpr->op==TK_IN?"LIST":"SCALAR", pParse->iNextSelectId ); sqlite3VdbeAddOp4(v, OP_Explain, pParse->iSelectId, 0, 0, zMsg, P4_DYNAMIC); } #endif switch( pExpr->op ){ case TK_IN: { char affinity; /* Affinity of the LHS of the IN */ KeyInfo keyInfo; /* Keyinfo for the generated table */ int addr; /* Address of OP_OpenEphemeral instruction */ Expr *pLeft = pExpr->pLeft; /* the LHS of the IN operator */ |
︙ | ︙ |
Changes to src/prepare.c.
︙ | ︙ | |||
624 625 626 627 628 629 630 | } rc = pParse->rc; #ifndef SQLITE_OMIT_EXPLAIN if( rc==SQLITE_OK && pParse->pVdbe && pParse->explain ){ static const char * const azColName[] = { "addr", "opcode", "p1", "p2", "p3", "p4", "p5", "comment", | | | | | 624 625 626 627 628 629 630 631 632 633 634 635 636 637 638 639 640 641 642 643 644 | } rc = pParse->rc; #ifndef SQLITE_OMIT_EXPLAIN if( rc==SQLITE_OK && pParse->pVdbe && pParse->explain ){ static const char * const azColName[] = { "addr", "opcode", "p1", "p2", "p3", "p4", "p5", "comment", "selectid", "order", "from", "detail" }; int iFirst, mx; if( pParse->explain==2 ){ sqlite3VdbeSetNumCols(pParse->pVdbe, 4); iFirst = 8; mx = 12; }else{ sqlite3VdbeSetNumCols(pParse->pVdbe, 8); iFirst = 0; mx = 8; } for(i=iFirst; i<mx; i++){ sqlite3VdbeSetColName(pParse->pVdbe, i-iFirst, COLNAME_NAME, |
︙ | ︙ |
Changes to src/select.c.
︙ | ︙ | |||
767 768 769 770 771 772 773 774 775 776 777 778 779 780 | pInfo->aColl[i] = pColl; pInfo->aSortOrder[i] = pItem->sortOrder; } } return pInfo; } /* ** If the inner loop was generated using a non-null pOrderBy argument, ** then the results were placed in a sorter. After the loop is terminated ** we need to run the sorter and output the results. The following ** routine generates the code needed to do that. */ | > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > | 767 768 769 770 771 772 773 774 775 776 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 812 813 814 815 816 817 818 819 820 821 822 823 824 825 826 827 828 829 830 831 832 833 834 835 836 837 838 839 840 841 842 843 844 845 846 847 848 849 850 851 852 853 854 855 856 857 858 859 860 861 862 | pInfo->aColl[i] = pColl; pInfo->aSortOrder[i] = pItem->sortOrder; } } return pInfo; } #ifndef SQLITE_OMIT_COMPOUND_SELECT /* ** Name of the connection operator, used for error messages. */ static const char *selectOpName(int id){ char *z; switch( id ){ case TK_ALL: z = "UNION ALL"; break; case TK_INTERSECT: z = "INTERSECT"; break; case TK_EXCEPT: z = "EXCEPT"; break; default: z = "UNION"; break; } return z; } #endif /* SQLITE_OMIT_COMPOUND_SELECT */ #ifndef SQLITE_OMIT_EXPLAIN /* ** Unless an "EXPLAIN QUERY PLAN" command is being processed, this function ** is a no-op. Otherwise, it adds a single row of output to the EQP result, ** where the caption is of the form: ** ** "USE TEMP B-TREE FOR xxx" ** ** where xxx is one of "DISTINCT", "ORDER BY" or "GROUP BY". Exactly which ** is determined by the zUsage argument. */ static void explainTempTable(Parse *pParse, const char *zUsage){ if( pParse->explain==2 ){ Vdbe *v = pParse->pVdbe; char *zMsg = sqlite3MPrintf(pParse->db, "USE TEMP B-TREE FOR %s", zUsage); sqlite3VdbeAddOp4(v, OP_Explain, pParse->iSelectId, 0, 0, zMsg, P4_DYNAMIC); } } /* ** Unless an "EXPLAIN QUERY PLAN" command is being processed, this function ** is a no-op. Otherwise, it adds a single row of output to the EQP result, ** where the caption is of one of the two forms: ** ** "COMPOSITE SUBQUERIES iSub1 and iSub2 (op)" ** "COMPOSITE SUBQUERIES iSub1 and iSub2 USING TEMP B-TREE (op)" ** ** where iSub1 and iSub2 are the integers passed as the corresponding ** function parameters, and op is the text representation of the parameter ** of the same name. The parameter "op" must be one of TK_UNION, TK_EXCEPT, ** TK_INTERSECT or TK_ALL. The first form is used if argument bUseTmp is ** false, or the second form if it is true. */ static void explainComposite( Parse *pParse, /* Parse context */ int op, /* One of TK_UNION, TK_EXCEPT etc. */ int iSub1, /* Subquery id 1 */ int iSub2, /* Subquery id 2 */ int bUseTmp /* True if a temp table was used */ ){ assert( op==TK_UNION || op==TK_EXCEPT || op==TK_INTERSECT || op==TK_ALL ); if( pParse->explain==2 ){ Vdbe *v = pParse->pVdbe; char *zMsg = sqlite3MPrintf( pParse->db, "COMPOUND SUBQUERIES %d AND %d %s(%s)", iSub1, iSub2, bUseTmp?"USING TEMP B-TREE ":"", selectOpName(op) ); sqlite3VdbeAddOp4(v, OP_Explain, pParse->iSelectId, 0, 0, zMsg, P4_DYNAMIC); } } /* ** Assign expression b to lvalue a. A second, no-op, version of this macro ** is provided when SQLITE_OMIT_EXPLAIN is defined. This allows the code ** in sqlite3Select() to assign values to structure member variables that ** only exist if SQLITE_OMIT_EXPLAIN is not defined without polluting the ** code with #ifndef directives. */ # define explainSetInteger(a, b) a = b #else /* No-op versions of the explainXXX() functions and macros. */ # define explainTempTable(y,z) # define explainComposite(v,w,x,y,z) # define explainSetInteger(y,z) #endif /* ** If the inner loop was generated using a non-null pOrderBy argument, ** then the results were placed in a sorter. After the loop is terminated ** we need to run the sorter and output the results. The following ** routine generates the code needed to do that. */ |
︙ | ︙ | |||
1114 1115 1116 1117 1118 1119 1120 | sqlite3VdbeSetColName(v, i, COLNAME_NAME, sqlite3DbStrDup(db, pEList->a[i].zSpan), SQLITE_DYNAMIC); } } generateColumnTypes(pParse, pTabList, pEList); } | < < < < < < < < < < < < < < < < | 1196 1197 1198 1199 1200 1201 1202 1203 1204 1205 1206 1207 1208 1209 | sqlite3VdbeSetColName(v, i, COLNAME_NAME, sqlite3DbStrDup(db, pEList->a[i].zSpan), SQLITE_DYNAMIC); } } generateColumnTypes(pParse, pTabList, pEList); } /* ** Given a an expression list (which is really the list of expressions ** that form the result set of a SELECT statement) compute appropriate ** column names for a table that would hold the expression list. ** ** All column names will be unique. ** |
︙ | ︙ | |||
1463 1464 1465 1466 1467 1468 1469 1470 1471 1472 1473 1474 1475 1476 | ){ int rc = SQLITE_OK; /* Success code from a subroutine */ Select *pPrior; /* Another SELECT immediately to our left */ Vdbe *v; /* Generate code to this VDBE */ SelectDest dest; /* Alternative data destination */ Select *pDelete = 0; /* Chain of simple selects to delete */ sqlite3 *db; /* Database connection */ /* Make sure there is no ORDER BY or LIMIT clause on prior SELECTs. Only ** the last (right-most) SELECT in the series may have an ORDER BY or LIMIT. */ assert( p && p->pPrior ); /* Calling function guarantees this much */ db = pParse->db; pPrior = p->pPrior; | > > > > | 1529 1530 1531 1532 1533 1534 1535 1536 1537 1538 1539 1540 1541 1542 1543 1544 1545 1546 | ){ int rc = SQLITE_OK; /* Success code from a subroutine */ Select *pPrior; /* Another SELECT immediately to our left */ Vdbe *v; /* Generate code to this VDBE */ SelectDest dest; /* Alternative data destination */ Select *pDelete = 0; /* Chain of simple selects to delete */ sqlite3 *db; /* Database connection */ #ifndef SQLITE_OMIT_EXPLAIN int iSub1; /* EQP id of left-hand query */ int iSub2; /* EQP id of right-hand query */ #endif /* Make sure there is no ORDER BY or LIMIT clause on prior SELECTs. Only ** the last (right-most) SELECT in the series may have an ORDER BY or LIMIT. */ assert( p && p->pPrior ); /* Calling function guarantees this much */ db = pParse->db; pPrior = p->pPrior; |
︙ | ︙ | |||
1523 1524 1525 1526 1527 1528 1529 1530 1531 1532 1533 1534 1535 1536 1537 1538 1539 1540 1541 1542 1543 1544 1545 1546 1547 1548 1549 | */ switch( p->op ){ case TK_ALL: { int addr = 0; assert( !pPrior->pLimit ); pPrior->pLimit = p->pLimit; pPrior->pOffset = p->pOffset; rc = sqlite3Select(pParse, pPrior, &dest); p->pLimit = 0; p->pOffset = 0; if( rc ){ goto multi_select_end; } p->pPrior = 0; p->iLimit = pPrior->iLimit; p->iOffset = pPrior->iOffset; if( p->iLimit ){ addr = sqlite3VdbeAddOp1(v, OP_IfZero, p->iLimit); VdbeComment((v, "Jump ahead if LIMIT reached")); } rc = sqlite3Select(pParse, p, &dest); testcase( rc!=SQLITE_OK ); pDelete = p->pPrior; p->pPrior = pPrior; if( addr ){ sqlite3VdbeJumpHere(v, addr); } | > > | 1593 1594 1595 1596 1597 1598 1599 1600 1601 1602 1603 1604 1605 1606 1607 1608 1609 1610 1611 1612 1613 1614 1615 1616 1617 1618 1619 1620 1621 | */ switch( p->op ){ case TK_ALL: { int addr = 0; assert( !pPrior->pLimit ); pPrior->pLimit = p->pLimit; pPrior->pOffset = p->pOffset; explainSetInteger(iSub1, pParse->iNextSelectId); rc = sqlite3Select(pParse, pPrior, &dest); p->pLimit = 0; p->pOffset = 0; if( rc ){ goto multi_select_end; } p->pPrior = 0; p->iLimit = pPrior->iLimit; p->iOffset = pPrior->iOffset; if( p->iLimit ){ addr = sqlite3VdbeAddOp1(v, OP_IfZero, p->iLimit); VdbeComment((v, "Jump ahead if LIMIT reached")); } explainSetInteger(iSub2, pParse->iNextSelectId); rc = sqlite3Select(pParse, p, &dest); testcase( rc!=SQLITE_OK ); pDelete = p->pPrior; p->pPrior = pPrior; if( addr ){ sqlite3VdbeJumpHere(v, addr); } |
︙ | ︙ | |||
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 1609 1610 1611 1612 1613 1614 1615 | assert( p->pEList ); } /* Code the SELECT statements to our left */ assert( !pPrior->pOrderBy ); sqlite3SelectDestInit(&uniondest, priorOp, unionTab); rc = sqlite3Select(pParse, pPrior, &uniondest); if( rc ){ goto multi_select_end; } /* Code the current SELECT statement */ if( p->op==TK_EXCEPT ){ op = SRT_Except; }else{ assert( p->op==TK_UNION ); op = SRT_Union; } p->pPrior = 0; pLimit = p->pLimit; p->pLimit = 0; pOffset = p->pOffset; p->pOffset = 0; uniondest.eDest = op; rc = sqlite3Select(pParse, p, &uniondest); testcase( rc!=SQLITE_OK ); /* Query flattening in sqlite3Select() might refill p->pOrderBy. ** Be sure to delete p->pOrderBy, therefore, to avoid a memory leak. */ sqlite3ExprListDelete(db, p->pOrderBy); pDelete = p->pPrior; p->pPrior = pPrior; | > > | 1655 1656 1657 1658 1659 1660 1661 1662 1663 1664 1665 1666 1667 1668 1669 1670 1671 1672 1673 1674 1675 1676 1677 1678 1679 1680 1681 1682 1683 1684 1685 1686 1687 1688 1689 | assert( p->pEList ); } /* Code the SELECT statements to our left */ assert( !pPrior->pOrderBy ); sqlite3SelectDestInit(&uniondest, priorOp, unionTab); explainSetInteger(iSub1, pParse->iNextSelectId); rc = sqlite3Select(pParse, pPrior, &uniondest); if( rc ){ goto multi_select_end; } /* Code the current SELECT statement */ if( p->op==TK_EXCEPT ){ op = SRT_Except; }else{ assert( p->op==TK_UNION ); op = SRT_Union; } p->pPrior = 0; pLimit = p->pLimit; p->pLimit = 0; pOffset = p->pOffset; p->pOffset = 0; uniondest.eDest = op; explainSetInteger(iSub2, pParse->iNextSelectId); rc = sqlite3Select(pParse, p, &uniondest); testcase( rc!=SQLITE_OK ); /* Query flattening in sqlite3Select() might refill p->pOrderBy. ** Be sure to delete p->pOrderBy, therefore, to avoid a memory leak. */ sqlite3ExprListDelete(db, p->pOrderBy); pDelete = p->pPrior; p->pPrior = pPrior; |
︙ | ︙ | |||
1667 1668 1669 1670 1671 1672 1673 1674 1675 1676 1677 1678 1679 1680 1681 1682 1683 1684 1685 1686 1687 1688 1689 1690 1691 1692 1693 1694 1695 1696 | p->addrOpenEphm[0] = addr; p->pRightmost->selFlags |= SF_UsesEphemeral; assert( p->pEList ); /* Code the SELECTs to our left into temporary table "tab1". */ sqlite3SelectDestInit(&intersectdest, SRT_Union, tab1); rc = sqlite3Select(pParse, pPrior, &intersectdest); if( rc ){ goto multi_select_end; } /* Code the current SELECT into temporary table "tab2" */ addr = sqlite3VdbeAddOp2(v, OP_OpenEphemeral, tab2, 0); assert( p->addrOpenEphm[1] == -1 ); p->addrOpenEphm[1] = addr; p->pPrior = 0; pLimit = p->pLimit; p->pLimit = 0; pOffset = p->pOffset; p->pOffset = 0; intersectdest.iParm = tab2; rc = sqlite3Select(pParse, p, &intersectdest); testcase( rc!=SQLITE_OK ); pDelete = p->pPrior; p->pPrior = pPrior; sqlite3ExprDelete(db, p->pLimit); p->pLimit = pLimit; p->pOffset = pOffset; | > > | 1741 1742 1743 1744 1745 1746 1747 1748 1749 1750 1751 1752 1753 1754 1755 1756 1757 1758 1759 1760 1761 1762 1763 1764 1765 1766 1767 1768 1769 1770 1771 1772 | p->addrOpenEphm[0] = addr; p->pRightmost->selFlags |= SF_UsesEphemeral; assert( p->pEList ); /* Code the SELECTs to our left into temporary table "tab1". */ sqlite3SelectDestInit(&intersectdest, SRT_Union, tab1); explainSetInteger(iSub1, pParse->iNextSelectId); rc = sqlite3Select(pParse, pPrior, &intersectdest); if( rc ){ goto multi_select_end; } /* Code the current SELECT into temporary table "tab2" */ addr = sqlite3VdbeAddOp2(v, OP_OpenEphemeral, tab2, 0); assert( p->addrOpenEphm[1] == -1 ); p->addrOpenEphm[1] = addr; p->pPrior = 0; pLimit = p->pLimit; p->pLimit = 0; pOffset = p->pOffset; p->pOffset = 0; intersectdest.iParm = tab2; explainSetInteger(iSub2, pParse->iNextSelectId); rc = sqlite3Select(pParse, p, &intersectdest); testcase( rc!=SQLITE_OK ); pDelete = p->pPrior; p->pPrior = pPrior; sqlite3ExprDelete(db, p->pLimit); p->pLimit = pLimit; p->pOffset = pOffset; |
︙ | ︙ | |||
1718 1719 1720 1721 1722 1723 1724 1725 1726 1727 1728 1729 1730 1731 | sqlite3VdbeAddOp2(v, OP_Next, tab1, iStart); sqlite3VdbeResolveLabel(v, iBreak); sqlite3VdbeAddOp2(v, OP_Close, tab2, 0); sqlite3VdbeAddOp2(v, OP_Close, tab1, 0); break; } } /* Compute collating sequences used by ** temporary tables needed to implement the compound select. ** Attach the KeyInfo structure to all temporary tables. ** ** This section is run by the right-most SELECT statement only. ** SELECT statements to the left always skip this part. The right-most | > > | 1794 1795 1796 1797 1798 1799 1800 1801 1802 1803 1804 1805 1806 1807 1808 1809 | sqlite3VdbeAddOp2(v, OP_Next, tab1, iStart); sqlite3VdbeResolveLabel(v, iBreak); sqlite3VdbeAddOp2(v, OP_Close, tab2, 0); sqlite3VdbeAddOp2(v, OP_Close, tab1, 0); break; } } explainComposite(pParse, p->op, iSub1, iSub2, p->op!=TK_ALL); /* Compute collating sequences used by ** temporary tables needed to implement the compound select. ** Attach the KeyInfo structure to all temporary tables. ** ** This section is run by the right-most SELECT statement only. ** SELECT statements to the left always skip this part. The right-most |
︙ | ︙ | |||
2062 2063 2064 2065 2066 2067 2068 2069 2070 2071 2072 2073 2074 2075 | int op; /* One of TK_ALL, TK_UNION, TK_EXCEPT, TK_INTERSECT */ KeyInfo *pKeyDup = 0; /* Comparison information for duplicate removal */ KeyInfo *pKeyMerge; /* Comparison information for merging rows */ sqlite3 *db; /* Database connection */ ExprList *pOrderBy; /* The ORDER BY clause */ int nOrderBy; /* Number of terms in the ORDER BY clause */ int *aPermute; /* Mapping from ORDER BY terms to result set columns */ assert( p->pOrderBy!=0 ); assert( pKeyDup==0 ); /* "Managed" code needs this. Ticket #3382. */ db = pParse->db; v = pParse->pVdbe; assert( v!=0 ); /* Already thrown the error if VDBE alloc failed */ labelEnd = sqlite3VdbeMakeLabel(v); | > > > > | 2140 2141 2142 2143 2144 2145 2146 2147 2148 2149 2150 2151 2152 2153 2154 2155 2156 2157 | int op; /* One of TK_ALL, TK_UNION, TK_EXCEPT, TK_INTERSECT */ KeyInfo *pKeyDup = 0; /* Comparison information for duplicate removal */ KeyInfo *pKeyMerge; /* Comparison information for merging rows */ sqlite3 *db; /* Database connection */ ExprList *pOrderBy; /* The ORDER BY clause */ int nOrderBy; /* Number of terms in the ORDER BY clause */ int *aPermute; /* Mapping from ORDER BY terms to result set columns */ #ifndef SQLITE_OMIT_EXPLAIN int iSub1; /* EQP id of left-hand query */ int iSub2; /* EQP id of right-hand query */ #endif assert( p->pOrderBy!=0 ); assert( pKeyDup==0 ); /* "Managed" code needs this. Ticket #3382. */ db = pParse->db; v = pParse->pVdbe; assert( v!=0 ); /* Already thrown the error if VDBE alloc failed */ labelEnd = sqlite3VdbeMakeLabel(v); |
︙ | ︙ | |||
2215 2216 2217 2218 2219 2220 2221 2222 2223 2224 2225 2226 2227 2228 2229 2230 2231 2232 2233 2234 2235 2236 2237 2238 2239 2240 2241 2242 | /* Generate a coroutine to evaluate the SELECT statement to the ** left of the compound operator - the "A" select. */ VdbeNoopComment((v, "Begin coroutine for left SELECT")); pPrior->iLimit = regLimitA; sqlite3Select(pParse, pPrior, &destA); sqlite3VdbeAddOp2(v, OP_Integer, 1, regEofA); sqlite3VdbeAddOp1(v, OP_Yield, regAddrA); VdbeNoopComment((v, "End coroutine for left SELECT")); /* Generate a coroutine to evaluate the SELECT statement on ** the right - the "B" select */ addrSelectB = sqlite3VdbeCurrentAddr(v); VdbeNoopComment((v, "Begin coroutine for right SELECT")); savedLimit = p->iLimit; savedOffset = p->iOffset; p->iLimit = regLimitB; p->iOffset = 0; sqlite3Select(pParse, p, &destB); p->iLimit = savedLimit; p->iOffset = savedOffset; sqlite3VdbeAddOp2(v, OP_Integer, 1, regEofB); sqlite3VdbeAddOp1(v, OP_Yield, regAddrB); VdbeNoopComment((v, "End coroutine for right SELECT")); | > > | 2297 2298 2299 2300 2301 2302 2303 2304 2305 2306 2307 2308 2309 2310 2311 2312 2313 2314 2315 2316 2317 2318 2319 2320 2321 2322 2323 2324 2325 2326 | /* Generate a coroutine to evaluate the SELECT statement to the ** left of the compound operator - the "A" select. */ VdbeNoopComment((v, "Begin coroutine for left SELECT")); pPrior->iLimit = regLimitA; explainSetInteger(iSub1, pParse->iNextSelectId); sqlite3Select(pParse, pPrior, &destA); sqlite3VdbeAddOp2(v, OP_Integer, 1, regEofA); sqlite3VdbeAddOp1(v, OP_Yield, regAddrA); VdbeNoopComment((v, "End coroutine for left SELECT")); /* Generate a coroutine to evaluate the SELECT statement on ** the right - the "B" select */ addrSelectB = sqlite3VdbeCurrentAddr(v); VdbeNoopComment((v, "Begin coroutine for right SELECT")); savedLimit = p->iLimit; savedOffset = p->iOffset; p->iLimit = regLimitB; p->iOffset = 0; explainSetInteger(iSub2, pParse->iNextSelectId); sqlite3Select(pParse, p, &destB); p->iLimit = savedLimit; p->iOffset = savedOffset; sqlite3VdbeAddOp2(v, OP_Integer, 1, regEofB); sqlite3VdbeAddOp1(v, OP_Yield, regAddrB); VdbeNoopComment((v, "End coroutine for right SELECT")); |
︙ | ︙ | |||
2359 2360 2361 2362 2363 2364 2365 2366 2367 2368 2369 2370 2371 2372 | if( p->pPrior ){ sqlite3SelectDelete(db, p->pPrior); } p->pPrior = pPrior; /*** TBD: Insert subroutine calls to close cursors on incomplete **** subqueries ****/ return SQLITE_OK; } #endif #if !defined(SQLITE_OMIT_SUBQUERY) || !defined(SQLITE_OMIT_VIEW) /* Forward Declarations */ static void substExprList(sqlite3*, ExprList*, int, ExprList*); | > | 2443 2444 2445 2446 2447 2448 2449 2450 2451 2452 2453 2454 2455 2456 2457 | if( p->pPrior ){ sqlite3SelectDelete(db, p->pPrior); } p->pPrior = pPrior; /*** TBD: Insert subroutine calls to close cursors on incomplete **** subqueries ****/ explainComposite(pParse, p->op, iSub1, iSub2, 0); return SQLITE_OK; } #endif #if !defined(SQLITE_OMIT_SUBQUERY) || !defined(SQLITE_OMIT_VIEW) /* Forward Declarations */ static void substExprList(sqlite3*, ExprList*, int, ExprList*); |
︙ | ︙ | |||
3585 3586 3587 3588 3589 3590 3591 3592 3593 3594 3595 3596 3597 3598 | int isDistinct; /* True if the DISTINCT keyword is present */ int distinct; /* Table to use for the distinct set */ int rc = 1; /* Value to return from this function */ int addrSortIndex; /* Address of an OP_OpenEphemeral instruction */ AggInfo sAggInfo; /* Information used by aggregate queries */ int iEnd; /* Address of the end of the query */ sqlite3 *db; /* The database connection */ db = pParse->db; if( p==0 || db->mallocFailed || pParse->nErr ){ return 1; } if( sqlite3AuthCheck(pParse, SQLITE_SELECT, 0, 0, 0) ) return 1; memset(&sAggInfo, 0, sizeof(sAggInfo)); | > > > > > | 3670 3671 3672 3673 3674 3675 3676 3677 3678 3679 3680 3681 3682 3683 3684 3685 3686 3687 3688 | int isDistinct; /* True if the DISTINCT keyword is present */ int distinct; /* Table to use for the distinct set */ int rc = 1; /* Value to return from this function */ int addrSortIndex; /* Address of an OP_OpenEphemeral instruction */ AggInfo sAggInfo; /* Information used by aggregate queries */ int iEnd; /* Address of the end of the query */ sqlite3 *db; /* The database connection */ #ifndef SQLITE_OMIT_EXPLAIN int iRestoreSelectId = pParse->iSelectId; pParse->iSelectId = pParse->iNextSelectId++; #endif db = pParse->db; if( p==0 || db->mallocFailed || pParse->nErr ){ return 1; } if( sqlite3AuthCheck(pParse, SQLITE_SELECT, 0, 0, 0) ) return 1; memset(&sAggInfo, 0, sizeof(sAggInfo)); |
︙ | ︙ | |||
3657 3658 3659 3660 3661 3662 3663 3664 3665 3666 3667 3668 3669 3670 | isAgg = 1; p->selFlags |= SF_Aggregate; } i = -1; }else{ sqlite3SelectDestInit(&dest, SRT_EphemTab, pItem->iCursor); assert( pItem->isPopulated==0 ); sqlite3Select(pParse, pSub, &dest); pItem->isPopulated = 1; } if( /*pParse->nErr ||*/ db->mallocFailed ){ goto select_end; } pParse->nHeight -= sqlite3SelectExprHeight(p); | > | 3747 3748 3749 3750 3751 3752 3753 3754 3755 3756 3757 3758 3759 3760 3761 | isAgg = 1; p->selFlags |= SF_Aggregate; } i = -1; }else{ sqlite3SelectDestInit(&dest, SRT_EphemTab, pItem->iCursor); assert( pItem->isPopulated==0 ); explainSetInteger(pItem->iSelectId, pParse->iNextSelectId); sqlite3Select(pParse, pSub, &dest); pItem->isPopulated = 1; } if( /*pParse->nErr ||*/ db->mallocFailed ){ goto select_end; } pParse->nHeight -= sqlite3SelectExprHeight(p); |
︙ | ︙ | |||
3692 3693 3694 3695 3696 3697 3698 | pLoop->pRightmost = p; pLoop->pNext = pRight; pRight = pLoop; } mxSelect = db->aLimit[SQLITE_LIMIT_COMPOUND_SELECT]; if( mxSelect && cnt>mxSelect ){ sqlite3ErrorMsg(pParse, "too many terms in compound SELECT"); | | | > > < | 3783 3784 3785 3786 3787 3788 3789 3790 3791 3792 3793 3794 3795 3796 3797 3798 3799 3800 3801 3802 3803 3804 3805 3806 3807 3808 3809 3810 3811 3812 3813 | pLoop->pRightmost = p; pLoop->pNext = pRight; pRight = pLoop; } mxSelect = db->aLimit[SQLITE_LIMIT_COMPOUND_SELECT]; if( mxSelect && cnt>mxSelect ){ sqlite3ErrorMsg(pParse, "too many terms in compound SELECT"); goto select_end; } } rc = multiSelect(pParse, p, pDest); explainSetInteger(pParse->iSelectId, iRestoreSelectId); return rc; } #endif /* If possible, rewrite the query to use GROUP BY instead of DISTINCT. ** GROUP BY might use an index, DISTINCT never does. */ assert( p->pGroupBy==0 || (p->selFlags & SF_Aggregate)!=0 ); if( (p->selFlags & (SF_Distinct|SF_Aggregate))==SF_Distinct ){ p->pGroupBy = sqlite3ExprListDup(db, p->pEList, 0); pGroupBy = p->pGroupBy; p->selFlags &= ~SF_Distinct; } /* If there is both a GROUP BY and an ORDER BY clause and they are ** identical, then disable the ORDER BY clause since the GROUP BY ** will cause elements to come out in the correct order. This is ** an optimization - the correct answer should result regardless. ** Use the SQLITE_GroupByOrder flag with SQLITE_TESTCTRL_OPTIMIZER |
︙ | ︙ | |||
3754 3755 3756 3757 3758 3759 3760 | /* Set the limiter. */ iEnd = sqlite3VdbeMakeLabel(v); computeLimitRegisters(pParse, p, iEnd); /* Open a virtual index to use for the distinct set. */ | | | 3846 3847 3848 3849 3850 3851 3852 3853 3854 3855 3856 3857 3858 3859 3860 | /* Set the limiter. */ iEnd = sqlite3VdbeMakeLabel(v); computeLimitRegisters(pParse, p, iEnd); /* Open a virtual index to use for the distinct set. */ if( p->selFlags & SF_Distinct ){ KeyInfo *pKeyInfo; assert( isAgg || pGroupBy ); distinct = pParse->nTab++; pKeyInfo = keyInfoFromExprList(pParse, p->pEList); sqlite3VdbeAddOp4(v, OP_OpenEphemeral, distinct, 0, 0, (char*)pKeyInfo, P4_KEYINFO_HANDOFF); sqlite3VdbeChangeP5(v, BTREE_UNORDERED); |
︙ | ︙ | |||
3913 3914 3915 3916 3917 3918 3919 3920 3921 3922 3923 3924 3925 3926 | ** in sorted order */ int regBase; int regRecord; int nCol; int nGroupBy; groupBySort = 1; nGroupBy = pGroupBy->nExpr; nCol = nGroupBy + 1; j = nGroupBy+1; for(i=0; i<sAggInfo.nColumn; i++){ if( sAggInfo.aCol[i].iSorterColumn>=j ){ nCol++; | > > > | 4005 4006 4007 4008 4009 4010 4011 4012 4013 4014 4015 4016 4017 4018 4019 4020 4021 | ** in sorted order */ int regBase; int regRecord; int nCol; int nGroupBy; explainTempTable(pParse, isDistinct && !(p->selFlags&SF_Distinct)?"DISTINCT":"GROUP BY"); groupBySort = 1; nGroupBy = pGroupBy->nExpr; nCol = nGroupBy + 1; j = nGroupBy+1; for(i=0; i<sAggInfo.nColumn; i++){ if( sAggInfo.aCol[i].iSorterColumn>=j ){ nCol++; |
︙ | ︙ | |||
4173 4174 4175 4176 4177 4178 4179 4180 4181 4182 4183 4184 4185 4186 4187 4188 4189 4190 4191 4192 4193 4194 4195 4196 4197 4198 4199 4200 4201 4202 4203 4204 4205 4206 4207 | selectInnerLoop(pParse, p, p->pEList, 0, 0, 0, -1, pDest, addrEnd, addrEnd); sqlite3ExprListDelete(db, pDel); } sqlite3VdbeResolveLabel(v, addrEnd); } /* endif aggregate query */ /* If there is an ORDER BY clause, then we need to sort the results ** and send them to the callback one by one. */ if( pOrderBy ){ generateSortTail(pParse, p, v, pEList->nExpr, pDest); } /* Jump here to skip this query */ sqlite3VdbeResolveLabel(v, iEnd); /* The SELECT was successfully coded. Set the return code to 0 ** to indicate no errors. */ rc = 0; /* Control jumps to here if an error is encountered above, or upon ** successful coding of the SELECT. */ select_end: /* Identify column names if results of the SELECT are to be output. */ if( rc==SQLITE_OK && pDest->eDest==SRT_Output ){ generateColumnNames(pParse, pTabList, pEList); } | > > > > > > | 4268 4269 4270 4271 4272 4273 4274 4275 4276 4277 4278 4279 4280 4281 4282 4283 4284 4285 4286 4287 4288 4289 4290 4291 4292 4293 4294 4295 4296 4297 4298 4299 4300 4301 4302 4303 4304 4305 4306 4307 4308 | selectInnerLoop(pParse, p, p->pEList, 0, 0, 0, -1, pDest, addrEnd, addrEnd); sqlite3ExprListDelete(db, pDel); } sqlite3VdbeResolveLabel(v, addrEnd); } /* endif aggregate query */ if( distinct>=0 ){ explainTempTable(pParse, "DISTINCT"); } /* If there is an ORDER BY clause, then we need to sort the results ** and send them to the callback one by one. */ if( pOrderBy ){ explainTempTable(pParse, "ORDER BY"); generateSortTail(pParse, p, v, pEList->nExpr, pDest); } /* Jump here to skip this query */ sqlite3VdbeResolveLabel(v, iEnd); /* The SELECT was successfully coded. Set the return code to 0 ** to indicate no errors. */ rc = 0; /* Control jumps to here if an error is encountered above, or upon ** successful coding of the SELECT. */ select_end: explainSetInteger(pParse->iSelectId, iRestoreSelectId); /* Identify column names if results of the SELECT are to be output. */ if( rc==SQLITE_OK && pDest->eDest==SRT_Output ){ generateColumnNames(pParse, pTabList, pEList); } |
︙ | ︙ |
Changes to src/sqliteInt.h.
︙ | ︙ | |||
1823 1824 1825 1826 1827 1828 1829 1830 1831 1832 1833 1834 1835 1836 | u8 notIndexed; /* True if there is a NOT INDEXED clause */ int iCursor; /* The VDBE cursor number used to access this table */ Expr *pOn; /* The ON clause of a join */ IdList *pUsing; /* The USING clause of a join */ Bitmask colUsed; /* Bit N (1<<N) set if column N of pTab is used */ char *zIndex; /* Identifier from "INDEXED BY <zIndex>" clause */ Index *pIndex; /* Index structure corresponding to zIndex, if any */ } a[1]; /* One entry for each identifier on the list */ }; /* ** Permitted values of the SrcList.a.jointype field */ #define JT_INNER 0x0001 /* Any kind of inner or cross join */ | > > > | 1823 1824 1825 1826 1827 1828 1829 1830 1831 1832 1833 1834 1835 1836 1837 1838 1839 | u8 notIndexed; /* True if there is a NOT INDEXED clause */ int iCursor; /* The VDBE cursor number used to access this table */ Expr *pOn; /* The ON clause of a join */ IdList *pUsing; /* The USING clause of a join */ Bitmask colUsed; /* Bit N (1<<N) set if column N of pTab is used */ char *zIndex; /* Identifier from "INDEXED BY <zIndex>" clause */ Index *pIndex; /* Index structure corresponding to zIndex, if any */ #ifndef SQLITE_OMIT_EXPLAIN int iSelectId; /* If pSelect!=0, the id of the sub-select in EQP */ #endif } a[1]; /* One entry for each identifier on the list */ }; /* ** Permitted values of the SrcList.a.jointype field */ #define JT_INNER 0x0001 /* Any kind of inner or cross join */ |
︙ | ︙ | |||
1855 1856 1857 1858 1859 1860 1861 1862 1863 1864 1865 1866 1867 1868 | ** pTerm is only used when wsFlags&WHERE_MULTI_OR is true. And pVtabIdx ** is only used when wsFlags&WHERE_VIRTUALTABLE is true. It is never the ** case that more than one of these conditions is true. */ struct WherePlan { u32 wsFlags; /* WHERE_* flags that describe the strategy */ u32 nEq; /* Number of == constraints */ union { Index *pIdx; /* Index when WHERE_INDEXED is true */ struct WhereTerm *pTerm; /* WHERE clause term for OR-search */ sqlite3_index_info *pVtabIdx; /* Virtual table index to use */ } u; }; | > | 1858 1859 1860 1861 1862 1863 1864 1865 1866 1867 1868 1869 1870 1871 1872 | ** pTerm is only used when wsFlags&WHERE_MULTI_OR is true. And pVtabIdx ** is only used when wsFlags&WHERE_VIRTUALTABLE is true. It is never the ** case that more than one of these conditions is true. */ struct WherePlan { u32 wsFlags; /* WHERE_* flags that describe the strategy */ u32 nEq; /* Number of == constraints */ double nRow; /* Estimated number of rows (for EQP) */ union { Index *pIdx; /* Index when WHERE_INDEXED is true */ struct WhereTerm *pTerm; /* WHERE clause term for OR-search */ sqlite3_index_info *pVtabIdx; /* Virtual table index to use */ } u; }; |
︙ | ︙ | |||
2209 2210 2211 2212 2213 2214 2215 2216 2217 2218 2219 2220 2221 2222 | u8 declareVtab; /* True if inside sqlite3_declare_vtab() */ int nVtabLock; /* Number of virtual tables to lock */ Table **apVtabLock; /* Pointer to virtual tables needing locking */ #endif int nHeight; /* Expression tree height of current sub-select */ Table *pZombieTab; /* List of Table objects to delete after code gen */ TriggerPrg *pTriggerPrg; /* Linked list of coded triggers */ }; #ifdef SQLITE_OMIT_VIRTUALTABLE #define IN_DECLARE_VTAB 0 #else #define IN_DECLARE_VTAB (pParse->declareVtab) #endif | > > > > > | 2213 2214 2215 2216 2217 2218 2219 2220 2221 2222 2223 2224 2225 2226 2227 2228 2229 2230 2231 | u8 declareVtab; /* True if inside sqlite3_declare_vtab() */ int nVtabLock; /* Number of virtual tables to lock */ Table **apVtabLock; /* Pointer to virtual tables needing locking */ #endif int nHeight; /* Expression tree height of current sub-select */ Table *pZombieTab; /* List of Table objects to delete after code gen */ TriggerPrg *pTriggerPrg; /* Linked list of coded triggers */ #ifndef SQLITE_OMIT_EXPLAIN int iSelectId; int iNextSelectId; #endif }; #ifdef SQLITE_OMIT_VIRTUALTABLE #define IN_DECLARE_VTAB 0 #else #define IN_DECLARE_VTAB (pParse->declareVtab) #endif |
︙ | ︙ |
Changes to src/vdbeaux.c.
︙ | ︙ | |||
1178 1179 1180 1181 1182 1183 1184 | pMem++; pMem->flags = MEM_Int; pMem->u.i = pOp->p2; /* P2 */ pMem->type = SQLITE_INTEGER; pMem++; | < | | | | < | 1178 1179 1180 1181 1182 1183 1184 1185 1186 1187 1188 1189 1190 1191 1192 1193 1194 1195 | pMem++; pMem->flags = MEM_Int; pMem->u.i = pOp->p2; /* P2 */ pMem->type = SQLITE_INTEGER; pMem++; pMem->flags = MEM_Int; pMem->u.i = pOp->p3; /* P3 */ pMem->type = SQLITE_INTEGER; pMem++; if( sqlite3VdbeMemGrow(pMem, 32, 0) ){ /* P4 */ assert( p->db->mallocFailed ); return SQLITE_ERROR; } pMem->flags = MEM_Dyn|MEM_Str|MEM_Term; z = displayP4(pOp, pMem->z, 32); |
︙ | ︙ | |||
1228 1229 1230 1231 1232 1233 1234 | #endif { pMem->flags = MEM_Null; /* Comment */ pMem->type = SQLITE_NULL; } } | | | 1226 1227 1228 1229 1230 1231 1232 1233 1234 1235 1236 1237 1238 1239 1240 | #endif { pMem->flags = MEM_Null; /* Comment */ pMem->type = SQLITE_NULL; } } p->nResColumn = 8 - 4*(p->explain-1); p->rc = SQLITE_OK; rc = SQLITE_ROW; } return rc; } #endif /* SQLITE_OMIT_EXPLAIN */ |
︙ | ︙ |
Changes to src/where.c.
︙ | ︙ | |||
188 189 190 191 192 193 194 | /* ** 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 */ | < | 188 189 190 191 192 193 194 195 196 197 198 199 200 201 | /* ** 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 */ 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. |
︙ | ︙ | |||
1617 1618 1619 1620 1621 1622 1623 | tempWC.a = pOrTerm; tempWC.nTerm = 1; bestIndex(pParse, &tempWC, pSrc, notReady, notValid, 0, &sTermCost); }else{ continue; } rTotal += sTermCost.rCost; | | < > | 1616 1617 1618 1619 1620 1621 1622 1623 1624 1625 1626 1627 1628 1629 1630 1631 1632 1633 1634 1635 1636 1637 1638 1639 1640 1641 1642 1643 1644 1645 1646 1647 1648 1649 1650 | tempWC.a = pOrTerm; tempWC.nTerm = 1; bestIndex(pParse, &tempWC, pSrc, notReady, notValid, 0, &sTermCost); }else{ continue; } rTotal += sTermCost.rCost; nRow += sTermCost.plan.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 ){ WHERETRACE(("... sorting increases OR cost %.9g to %.9g\n", rTotal, rTotal+nRow*estLog(nRow))); rTotal += nRow*estLog(nRow); } /* 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->used = used; pCost->plan.nRow = nRow; pCost->plan.wsFlags = flags; pCost->plan.u.pTerm = pTerm; } } } #endif /* SQLITE_OMIT_OR_OPTIMIZATION */ } |
︙ | ︙ | |||
1721 1722 1723 1724 1725 1726 1727 | /* Search for any equality comparison term */ pWCEnd = &pWC->a[pWC->nTerm]; for(pTerm=pWC->a; pTerm<pWCEnd; pTerm++){ if( termCanDriveIndex(pTerm, pSrc, notReady) ){ WHERETRACE(("auto-index reduces cost from %.2f to %.2f\n", pCost->rCost, costTempIdx)); pCost->rCost = costTempIdx; | | | 1720 1721 1722 1723 1724 1725 1726 1727 1728 1729 1730 1731 1732 1733 1734 | /* Search for any equality comparison term */ pWCEnd = &pWC->a[pWC->nTerm]; for(pTerm=pWC->a; pTerm<pWCEnd; pTerm++){ if( termCanDriveIndex(pTerm, pSrc, notReady) ){ WHERETRACE(("auto-index reduces cost from %.2f to %.2f\n", pCost->rCost, costTempIdx)); pCost->rCost = costTempIdx; pCost->plan.nRow = logN + 1; pCost->plan.wsFlags = WHERE_TEMP_INDEX; pCost->used = pTerm->prereqRight; break; } } } #else |
︙ | ︙ | |||
2794 2795 2796 2797 2798 2799 2800 | notReady, nRow, cost, used )); /* If this index is the best we have seen so far, then record this ** index and its cost in the pCost structure. */ if( (!pIdx || wsFlags) | | < > | 2793 2794 2795 2796 2797 2798 2799 2800 2801 2802 2803 2804 2805 2806 2807 2808 2809 2810 2811 | notReady, nRow, cost, used )); /* If this index is the best we have seen so far, then record this ** index and its cost in the pCost structure. */ if( (!pIdx || wsFlags) && (cost<pCost->rCost || (cost<=pCost->rCost && nRow<pCost->plan.nRow)) ){ pCost->rCost = cost; pCost->used = used; pCost->plan.nRow = nRow; pCost->plan.wsFlags = (wsFlags&wsFlagMask); pCost->plan.nEq = nEq; pCost->plan.u.pIdx = pIdx; } /* If there was an INDEXED BY clause, then only that one index is ** considered. */ |
︙ | ︙ | |||
3126 3127 3128 3129 3130 3131 3132 3133 3134 3135 3136 3137 3138 3139 | } } } } *pzAff = zAff; return regBase; } /* ** Generate code for the start of the iLevel-th loop in the WHERE clause ** implementation described by pWInfo. */ static Bitmask codeOneLoopStart( WhereInfo *pWInfo, /* Complete information about the WHERE clause */ | > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > | 3125 3126 3127 3128 3129 3130 3131 3132 3133 3134 3135 3136 3137 3138 3139 3140 3141 3142 3143 3144 3145 3146 3147 3148 3149 3150 3151 3152 3153 3154 3155 3156 3157 3158 3159 3160 3161 3162 3163 3164 3165 3166 3167 3168 3169 3170 3171 3172 3173 3174 3175 3176 3177 3178 3179 3180 3181 3182 3183 3184 3185 3186 3187 3188 3189 3190 3191 3192 3193 3194 3195 3196 3197 3198 3199 3200 3201 3202 3203 3204 3205 3206 3207 3208 3209 3210 3211 3212 3213 3214 3215 3216 3217 3218 3219 3220 3221 3222 3223 3224 3225 3226 3227 3228 3229 3230 3231 3232 3233 3234 3235 3236 3237 3238 3239 3240 3241 3242 3243 3244 3245 3246 3247 3248 3249 3250 3251 3252 3253 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 | } } } } *pzAff = zAff; return regBase; } #ifndef SQLITE_OMIT_EXPLAIN /* ** This routine is a helper for explainIndexRange() below ** ** pStr holds the text of an expression that we are building up one term ** at a time. This routine adds a new term to the end of the expression. ** Terms are separated by AND so add the "AND" text for second and subsequent ** terms only. */ static void explainAppendTerm( StrAccum *pStr, /* The text expression being built */ int iTerm, /* Index of this term. First is zero */ const char *zColumn, /* Name of the column */ const char *zOp /* Name of the operator */ ){ if( iTerm ) sqlite3StrAccumAppend(pStr, " AND ", 5); sqlite3StrAccumAppend(pStr, zColumn, -1); sqlite3StrAccumAppend(pStr, zOp, 1); sqlite3StrAccumAppend(pStr, "?", 1); } /* ** Argument pLevel describes a strategy for scanning table pTab. This ** function returns a pointer to a string buffer containing a description ** of the subset of table rows scanned by the strategy in the form of an ** SQL expression. Or, if all rows are scanned, NULL is returned. ** ** For example, if the query: ** ** SELECT * FROM t1 WHERE a=1 AND b>2; ** ** is run and there is an index on (a, b), then this function returns a ** string similar to: ** ** "a=? AND b>?" ** ** The returned pointer points to memory obtained from sqlite3DbMalloc(). ** It is the responsibility of the caller to free the buffer when it is ** no longer required. */ static char *explainIndexRange(sqlite3 *db, WhereLevel *pLevel, Table *pTab){ WherePlan *pPlan = &pLevel->plan; Index *pIndex = pPlan->u.pIdx; int nEq = pPlan->nEq; int i, j; Column *aCol = pTab->aCol; int *aiColumn = pIndex->aiColumn; StrAccum txt; if( nEq==0 && (pPlan->wsFlags & (WHERE_BTM_LIMIT|WHERE_TOP_LIMIT))==0 ){ return 0; } sqlite3StrAccumInit(&txt, 0, 0, SQLITE_MAX_LENGTH); sqlite3StrAccumAppend(&txt, " (", 2); for(i=0; i<nEq; i++){ explainAppendTerm(&txt, i, aCol[aiColumn[i]].zName, "="); } j = i; if( pPlan->wsFlags&WHERE_BTM_LIMIT ){ explainAppendTerm(&txt, i++, aCol[aiColumn[j]].zName, ">"); } if( pPlan->wsFlags&WHERE_TOP_LIMIT ){ explainAppendTerm(&txt, i, aCol[aiColumn[j]].zName, "<"); } sqlite3StrAccumAppend(&txt, ")", 1); return sqlite3StrAccumFinish(&txt); } /* ** This function is a no-op unless currently processing an EXPLAIN QUERY PLAN ** command. If the query being compiled is an EXPLAIN QUERY PLAN, a single ** record is added to the output to describe the table scan strategy in ** pLevel. */ static void explainOneScan( Parse *pParse, /* Parse context */ SrcList *pTabList, /* Table list this loop refers to */ WhereLevel *pLevel, /* Scan to write OP_Explain opcode for */ int iLevel, /* Value for "level" column of output */ int iFrom, /* Value for "from" column of output */ u16 wctrlFlags /* Flags passed to sqlite3WhereBegin() */ ){ if( pParse->explain==2 ){ u32 flags = pLevel->plan.wsFlags; struct SrcList_item *pItem = &pTabList->a[pLevel->iFrom]; Vdbe *v = pParse->pVdbe; /* VM being constructed */ sqlite3 *db = pParse->db; /* Database handle */ char *zMsg; /* Text to add to EQP output */ sqlite3_int64 nRow; /* Expected number of rows visited by scan */ int iId = pParse->iSelectId; /* Select id (left-most output column) */ int isSearch; /* True for a SEARCH. False for SCAN. */ if( (flags&WHERE_MULTI_OR) || (wctrlFlags&WHERE_ONETABLE_ONLY) ) return; isSearch = (pLevel->plan.nEq>0 || flags&(WHERE_BTM_LIMIT|WHERE_TOP_LIMIT)); zMsg = sqlite3MPrintf(db, "%s", isSearch?"SEARCH":"SCAN"); if( pItem->pSelect ){ zMsg = sqlite3MAppendf(db, zMsg, "%s SUBQUERY %d", zMsg,pItem->iSelectId); }else{ zMsg = sqlite3MAppendf(db, zMsg, "%s TABLE %s", zMsg, pItem->zName); } if( pItem->zAlias ){ zMsg = sqlite3MAppendf(db, zMsg, "%s AS %s", zMsg, pItem->zAlias); } if( (flags & WHERE_INDEXED)!=0 ){ char *zWhere = explainIndexRange(db, pLevel, pItem->pTab); zMsg = sqlite3MAppendf(db, zMsg, "%s USING %s%sINDEX%s%s%s", zMsg, ((flags & WHERE_TEMP_INDEX)?"AUTOMATIC ":""), ((flags & WHERE_IDX_ONLY)?"COVERING ":""), ((flags & WHERE_TEMP_INDEX)?"":" "), ((flags & WHERE_TEMP_INDEX)?"": pLevel->plan.u.pIdx->zName), zWhere ); sqlite3DbFree(db, zWhere); }else if( flags & (WHERE_ROWID_EQ|WHERE_ROWID_RANGE) ){ zMsg = sqlite3MAppendf(db, zMsg, "%s USING INTEGER PRIMARY KEY", zMsg); if( flags&WHERE_ROWID_EQ ){ zMsg = sqlite3MAppendf(db, zMsg, "%s (rowid=?)", zMsg); }else if( flags&WHERE_BTM_LIMIT && flags&WHERE_TOP_LIMIT ){ zMsg = sqlite3MAppendf(db, zMsg, "%s (rowid>? AND rowid<?)", zMsg); }else if( flags&WHERE_BTM_LIMIT ){ zMsg = sqlite3MAppendf(db, zMsg, "%s (rowid>?)", zMsg); }else if( flags&WHERE_TOP_LIMIT ){ zMsg = sqlite3MAppendf(db, zMsg, "%s (rowid<?)", zMsg); } } #ifndef SQLITE_OMIT_VIRTUALTABLE else if( (flags & WHERE_VIRTUALTABLE)!=0 ){ sqlite3_index_info *pVtabIdx = pLevel->plan.u.pVtabIdx; zMsg = sqlite3MAppendf(db, zMsg, "%s VIRTUAL TABLE INDEX %d:%s", zMsg, pVtabIdx->idxNum, pVtabIdx->idxStr); } #endif if( wctrlFlags&(WHERE_ORDERBY_MIN|WHERE_ORDERBY_MAX) ){ nRow = 1; }else{ nRow = (sqlite3_int64)pLevel->plan.nRow; } zMsg = sqlite3MAppendf(db, zMsg, "%s (~%lld rows)", zMsg, nRow); sqlite3VdbeAddOp4(v, OP_Explain, iId, iLevel, iFrom, zMsg, P4_DYNAMIC); } } #else # define explainOneScan(u,v,w,x,y,z) #endif /* SQLITE_OMIT_EXPLAIN */ /* ** Generate code for the start of the iLevel-th loop in the WHERE clause ** implementation described by pWInfo. */ static Bitmask codeOneLoopStart( WhereInfo *pWInfo, /* Complete information about the WHERE clause */ |
︙ | ︙ | |||
3668 3669 3670 3671 3672 3673 3674 3675 3676 3677 3678 3679 3680 3681 | if( pOrTerm->leftCursor==iCur || pOrTerm->eOperator==WO_AND ){ WhereInfo *pSubWInfo; /* Info for single OR-term scan */ /* Loop through table entries that match term pOrTerm. */ pSubWInfo = sqlite3WhereBegin(pParse, pOrTab, pOrTerm->pExpr, 0, WHERE_OMIT_OPEN | WHERE_OMIT_CLOSE | WHERE_FORCE_TABLE | WHERE_ONETABLE_ONLY); if( pSubWInfo ){ if( (wctrlFlags & WHERE_DUPLICATES_OK)==0 ){ int iSet = ((ii==pOrWc->nTerm-1)?-1:ii); int r; r = sqlite3ExprCodeGetColumn(pParse, pTabItem->pTab, -1, iCur, regRowid); sqlite3VdbeAddOp4Int(v, OP_RowSetTest, regRowset, sqlite3VdbeCurrentAddr(v)+2, r, iSet); | > > > | 3818 3819 3820 3821 3822 3823 3824 3825 3826 3827 3828 3829 3830 3831 3832 3833 3834 | if( pOrTerm->leftCursor==iCur || pOrTerm->eOperator==WO_AND ){ WhereInfo *pSubWInfo; /* Info for single OR-term scan */ /* Loop through table entries that match term pOrTerm. */ pSubWInfo = sqlite3WhereBegin(pParse, pOrTab, pOrTerm->pExpr, 0, WHERE_OMIT_OPEN | WHERE_OMIT_CLOSE | WHERE_FORCE_TABLE | WHERE_ONETABLE_ONLY); if( pSubWInfo ){ explainOneScan( pParse, pOrTab, &pSubWInfo->a[0], iLevel, pLevel->iFrom, 0 ); if( (wctrlFlags & WHERE_DUPLICATES_OK)==0 ){ int iSet = ((ii==pOrWc->nTerm-1)?-1:ii); int r; r = sqlite3ExprCodeGetColumn(pParse, pTabItem->pTab, -1, iCur, regRowid); sqlite3VdbeAddOp4Int(v, OP_RowSetTest, regRowset, sqlite3VdbeCurrentAddr(v)+2, r, iSet); |
︙ | ︙ | |||
4180 4181 4182 4183 4184 4185 4186 | */ if( (sCost.used¬Ready)==0 /* (1) */ && (bestJ<0 || (notIndexed&m)!=0 /* (2) */ || (sCost.plan.wsFlags & WHERE_NOT_FULLSCAN)!=0) && (nUnconstrained==0 || pTabItem->pIndex==0 /* (3) */ || NEVER((sCost.plan.wsFlags & WHERE_NOT_FULLSCAN)!=0)) && (bestJ<0 || sCost.rCost<bestPlan.rCost /* (4) */ | | > | | > | > | 4333 4334 4335 4336 4337 4338 4339 4340 4341 4342 4343 4344 4345 4346 4347 4348 4349 4350 4351 4352 4353 4354 4355 4356 4357 4358 4359 4360 4361 4362 4363 4364 4365 4366 4367 4368 4369 4370 4371 4372 4373 4374 4375 4376 4377 4378 4379 4380 | */ if( (sCost.used¬Ready)==0 /* (1) */ && (bestJ<0 || (notIndexed&m)!=0 /* (2) */ || (sCost.plan.wsFlags & WHERE_NOT_FULLSCAN)!=0) && (nUnconstrained==0 || pTabItem->pIndex==0 /* (3) */ || NEVER((sCost.plan.wsFlags & WHERE_NOT_FULLSCAN)!=0)) && (bestJ<0 || sCost.rCost<bestPlan.rCost /* (4) */ || (sCost.rCost<=bestPlan.rCost && sCost.plan.nRow<bestPlan.plan.nRow)) ){ WHERETRACE(("=== table %d is best so far" " with cost=%g and nRow=%g\n", j, sCost.rCost, sCost.plan.nRow)); 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" " with cost=%g and nRow=%g\n", bestJ, pLevel-pWInfo->a, bestPlan.rCost, bestPlan.plan.nRow)); if( (bestPlan.plan.wsFlags & WHERE_ORDERBY)!=0 ){ *ppOrderBy = 0; } andFlags &= bestPlan.plan.wsFlags; pLevel->plan = bestPlan.plan; testcase( bestPlan.plan.wsFlags & WHERE_INDEXED ); testcase( bestPlan.plan.wsFlags & WHERE_TEMP_INDEX ); if( bestPlan.plan.wsFlags & (WHERE_INDEXED|WHERE_TEMP_INDEX) ){ pLevel->iIdxCur = pParse->nTab++; }else{ pLevel->iIdxCur = -1; } notReady &= ~getMask(pMaskSet, pTabList->a[bestJ].iCursor); pLevel->iFrom = (u8)bestJ; if( bestPlan.plan.nRow>=(double)1 ){ pParse->nQueryLoop *= bestPlan.plan.nRow; } /* Check that if the table scanned by this loop iteration had an ** INDEXED BY clause attached to it, that the named index is being ** used for the scan. If not, then query compilation has failed. ** Return an error. */ pIdx = pTabList->a[bestJ].pIndex; |
︙ | ︙ | |||
4262 4263 4264 4265 4266 4267 4268 | */ sqlite3CodeVerifySchema(pParse, -1); /* Insert the cookie verifier Goto */ notReady = ~(Bitmask)0; for(i=0, pLevel=pWInfo->a; i<nTabList; i++, pLevel++){ Table *pTab; /* Table to open */ int iDb; /* Index of database containing table/index */ | < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < < | 4418 4419 4420 4421 4422 4423 4424 4425 4426 4427 4428 4429 4430 4431 | */ sqlite3CodeVerifySchema(pParse, -1); /* Insert the cookie verifier Goto */ notReady = ~(Bitmask)0; for(i=0, pLevel=pWInfo->a; i<nTabList; i++, pLevel++){ Table *pTab; /* Table to open */ int iDb; /* Index of database containing table/index */ pTabItem = &pTabList->a[pLevel->iFrom]; pTab = pTabItem->pTab; pLevel->iTabCur = pTabItem->iCursor; iDb = sqlite3SchemaToIndex(db, pTab->pSchema); if( (pTab->tabFlags & TF_Ephemeral)!=0 || pTab->pSelect ){ /* Do nothing */ }else |
︙ | ︙ | |||
4351 4352 4353 4354 4355 4356 4357 4358 | /* Generate the code to do the search. Each iteration of the for ** loop below generates code for a single nested loop of the VM ** program. */ notReady = ~(Bitmask)0; for(i=0; i<nTabList; i++){ notReady = codeOneLoopStart(pWInfo, i, wctrlFlags, notReady); | > > | | 4476 4477 4478 4479 4480 4481 4482 4483 4484 4485 4486 4487 4488 4489 4490 4491 4492 4493 | /* Generate the code to do the search. Each iteration of the for ** loop below generates code for a single nested loop of the VM ** program. */ notReady = ~(Bitmask)0; for(i=0; i<nTabList; i++){ WhereLevel *pLevel = &pWInfo->a[i]; explainOneScan(pParse, pTabList, pLevel, i, pLevel->iFrom, wctrlFlags); notReady = codeOneLoopStart(pWInfo, i, wctrlFlags, notReady); pWInfo->iContinue = pLevel->addrCont; } #ifdef SQLITE_TEST /* For testing and debugging use only */ /* Record in the query plan information about the current table ** and the index used to access it (if any). If the table itself ** is not used, its name is just '{}'. If no index is used ** the index is listed as "{}". If the primary key is used the |
︙ | ︙ |
Changes to test/autoindex1.test.
︙ | ︙ | |||
136 137 138 139 140 141 142 | } } {4087} # Ticket [8011086c85c6c404014c947fcf3eb9f42b184a0d] from 2010-07-08 # Make sure automatic indices are not created for the RHS of an IN expression # that is not a correlated subquery. # | | < | | | | | > > > > | < | < | | | > > > > | < | < | | | | > > > > | < | < | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | > > > > > > > | < | 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 | } } {4087} # Ticket [8011086c85c6c404014c947fcf3eb9f42b184a0d] from 2010-07-08 # Make sure automatic indices are not created for the RHS of an IN expression # that is not a correlated subquery. # do_execsql_test autoindex1-500 { CREATE TABLE t501(a INTEGER PRIMARY KEY, b); CREATE TABLE t502(x INTEGER PRIMARY KEY, y); EXPLAIN QUERY PLAN SELECT b FROM t501 WHERE t501.a IN (SELECT x FROM t502 WHERE y=?); } { 0 0 0 {SEARCH TABLE t501 USING INTEGER PRIMARY KEY (rowid=?) (~25 rows)} 0 0 0 {EXECUTE LIST SUBQUERY 1} 1 0 0 {SCAN TABLE t502 (~100000 rows)} } do_execsql_test autoindex1-501 { EXPLAIN QUERY PLAN SELECT b FROM t501 WHERE t501.a IN (SELECT x FROM t502 WHERE y=t501.b); } { 0 0 0 {SCAN TABLE t501 (~500000 rows)} 0 0 0 {EXECUTE CORRELATED LIST SUBQUERY 1} 1 0 0 {SEARCH TABLE t502 USING AUTOMATIC COVERING INDEX (y=?) (~7 rows)} } do_execsql_test autoindex1-502 { EXPLAIN QUERY PLAN SELECT b FROM t501 WHERE t501.a=123 AND t501.a IN (SELECT x FROM t502 WHERE y=t501.b); } { 0 0 0 {SEARCH TABLE t501 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)} 0 0 0 {EXECUTE CORRELATED LIST SUBQUERY 1} 1 0 0 {SCAN TABLE t502 (~100000 rows)} } # The following code checks a performance regression reported on the # mailing list on 2010-10-19. The problem is that the nRowEst field # of ephermeral tables was not being initialized correctly and so no # automatic index was being created for the emphemeral table when it was # used as part of a join. # do_execsql_test autoindex1-600 { CREATE TABLE flock_owner( owner_rec_id INTEGER CONSTRAINT flock_owner_key PRIMARY KEY, flock_no VARCHAR(6) NOT NULL REFERENCES flock (flock_no), owner_person_id INTEGER NOT NULL REFERENCES person (person_id), owner_change_date TEXT, last_changed TEXT NOT NULL, CONSTRAINT fo_owner_date UNIQUE (flock_no, owner_change_date) ); CREATE TABLE sheep ( Sheep_No char(7) NOT NULL, Date_of_Birth char(8), Sort_DoB text, Flock_Book_Vol char(2), Breeder_No char(6), Breeder_Person integer, Originating_Flock char(6), Registering_Flock char(6), Tag_Prefix char(9), Tag_No char(15), Sort_Tag_No integer, Breeders_Temp_Tag char(15), Sex char(1), Sheep_Name char(32), Sire_No char(7), Dam_No char(7), Register_Code char(1), Colour char(48), Colour_Code char(2), Pattern_Code char(8), Horns char(1), Litter_Size char(1), Coeff_of_Inbreeding real, Date_of_Registration text, Date_Last_Changed text, UNIQUE(Sheep_No)); CREATE INDEX fo_flock_no_index ON flock_owner (flock_no); CREATE INDEX fo_owner_change_date_index ON flock_owner (owner_change_date); CREATE INDEX fo_owner_person_id_index ON flock_owner (owner_person_id); CREATE INDEX sheep_org_flock_index ON sheep (originating_flock); CREATE INDEX sheep_reg_flock_index ON sheep (registering_flock); EXPLAIN QUERY PLAN SELECT x.sheep_no, x.registering_flock, x.date_of_registration FROM sheep x LEFT JOIN (SELECT s.sheep_no, prev.flock_no, prev.owner_person_id, s.date_of_registration, prev.owner_change_date FROM sheep s JOIN flock_owner prev ON s.registering_flock = prev.flock_no AND (prev.owner_change_date <= s.date_of_registration || ' 00:00:00') WHERE NOT EXISTS (SELECT 'x' FROM flock_owner later WHERE prev.flock_no = later.flock_no AND later.owner_change_date > prev.owner_change_date AND later.owner_change_date <= s.date_of_registration||' 00:00:00') ) y ON x.sheep_no = y.sheep_no WHERE y.sheep_no IS NULL ORDER BY x.registering_flock; } { 1 0 0 {SCAN TABLE sheep AS s (~1000000 rows)} 1 1 1 {SEARCH TABLE flock_owner AS prev USING INDEX sqlite_autoindex_flock_owner_1 (flock_no=? AND owner_change_date<?) (~2 rows)} 1 0 0 {EXECUTE CORRELATED SCALAR SUBQUERY 2} 2 0 0 {SEARCH TABLE flock_owner AS later USING COVERING INDEX sqlite_autoindex_flock_owner_1 (flock_no=? AND owner_change_date>? AND owner_change_date<?) (~1 rows)} 0 0 0 {SCAN TABLE sheep AS x USING INDEX sheep_reg_flock_index (~1000000 rows)} 0 1 1 {SEARCH SUBQUERY 1 AS y USING AUTOMATIC COVERING INDEX (sheep_no=?) (~7 rows)} } finish_test |
Changes to test/e_createtable.test.
︙ | ︙ | |||
1369 1370 1371 1372 1373 1374 1375 | # do_execsql_test 4.10.0 { CREATE TABLE t1(a, b PRIMARY KEY); CREATE TABLE t2(a, b, c, UNIQUE(b, c)); } do_createtable_tests 4.10 { 1 "EXPLAIN QUERY PLAN SELECT * FROM t1 WHERE b = 5" | | | | | 1369 1370 1371 1372 1373 1374 1375 1376 1377 1378 1379 1380 1381 1382 1383 1384 1385 1386 1387 1388 1389 | # do_execsql_test 4.10.0 { CREATE TABLE t1(a, b PRIMARY KEY); CREATE TABLE t2(a, b, c, UNIQUE(b, c)); } do_createtable_tests 4.10 { 1 "EXPLAIN QUERY PLAN SELECT * FROM t1 WHERE b = 5" {0 0 0 {SEARCH TABLE t1 USING INDEX sqlite_autoindex_t1_1 (b=?) (~1 rows)}} 2 "EXPLAIN QUERY PLAN SELECT * FROM t2 ORDER BY b, c" {0 0 0 {SCAN TABLE t2 USING INDEX sqlite_autoindex_t2_1 (~1000000 rows)}} 3 "EXPLAIN QUERY PLAN SELECT * FROM t2 WHERE b=10 AND c>10" {0 0 0 {SEARCH TABLE t2 USING INDEX sqlite_autoindex_t2_1 (b=? AND c>?) (~3 rows)}} } # EVIDENCE-OF: R-45493-35653 A CHECK constraint may be attached to a # column definition or specified as a table constraint. In practice it # makes no difference. # # All the tests that deal with CHECK constraints below (4.11.* and |
︙ | ︙ |
Changes to test/e_fkey.test.
︙ | ︙ | |||
964 965 966 967 968 969 970 | trackid INTEGER, trackname TEXT, trackartist INTEGER, FOREIGN KEY(trackartist) REFERENCES artist(artistid) ); } } {} | | < | | | > > > | < | < | | > > > | < | 964 965 966 967 968 969 970 971 972 973 974 975 976 977 978 979 980 981 982 983 984 985 986 987 988 989 990 991 992 | trackid INTEGER, trackname TEXT, trackartist INTEGER, FOREIGN KEY(trackartist) REFERENCES artist(artistid) ); } } {} do_execsql_test e_fkey-25.2 { PRAGMA foreign_keys = OFF; EXPLAIN QUERY PLAN DELETE FROM artist WHERE 1; EXPLAIN QUERY PLAN SELECT rowid FROM track WHERE trackartist = ?; } { 0 0 0 {SCAN TABLE artist (~1000000 rows)} 0 0 0 {SCAN TABLE track (~100000 rows)} } do_execsql_test e_fkey-25.3 { PRAGMA foreign_keys = ON; EXPLAIN QUERY PLAN DELETE FROM artist WHERE 1; } { 0 0 0 {SCAN TABLE artist (~1000000 rows)} 0 0 0 {SCAN TABLE track (~100000 rows)} } do_test e_fkey-25.4 { execsql { INSERT INTO artist VALUES(5, 'artist 5'); INSERT INTO artist VALUES(6, 'artist 6'); INSERT INTO artist VALUES(7, 'artist 7'); INSERT INTO track VALUES(1, 'track 1', 5); INSERT INTO track VALUES(2, 'track 2', 6); |
︙ | ︙ | |||
1089 1090 1091 1092 1093 1094 1095 | ); CREATE INDEX trackindex ON track(trackartist); } } {} do_test e_fkey-27.2 { eqp { INSERT INTO artist VALUES(?, ?) } } {} | | | | | | | < > | | | | | < > | 1091 1092 1093 1094 1095 1096 1097 1098 1099 1100 1101 1102 1103 1104 1105 1106 1107 1108 1109 1110 1111 1112 1113 1114 1115 1116 1117 | ); CREATE INDEX trackindex ON track(trackartist); } } {} do_test e_fkey-27.2 { eqp { INSERT INTO artist VALUES(?, ?) } } {} do_execsql_test e_fkey-27.3 { EXPLAIN QUERY PLAN UPDATE artist SET artistid = ?, artistname = ? } { 0 0 0 {SCAN TABLE artist (~1000000 rows)} 0 0 0 {SEARCH TABLE track USING COVERING INDEX trackindex (trackartist=?) (~10 rows)} 0 0 0 {SEARCH TABLE track USING COVERING INDEX trackindex (trackartist=?) (~10 rows)} } do_execsql_test e_fkey-27.4 { EXPLAIN QUERY PLAN DELETE FROM artist } { 0 0 0 {SCAN TABLE artist (~1000000 rows)} 0 0 0 {SEARCH TABLE track USING COVERING INDEX trackindex (trackartist=?) (~10 rows)} } ########################################################################### ### SECTION 4.1: Composite Foreign Key Constraints ########################################################################### #------------------------------------------------------------------------- |
︙ | ︙ |
Added test/eqp.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 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 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 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 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 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 | # 2010 November 6 # # 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 set testprefix eqp #------------------------------------------------------------------------- # # eqp-1.*: Assorted tests. # eqp-2.*: Tests for single select statements. # eqp-3.*: Select statements that execute sub-selects. # eqp-4.*: Compound select statements. # proc do_eqp_test {name sql res} { uplevel do_execsql_test $name [list "EXPLAIN QUERY PLAN $sql"] [list $res] } proc det {args} { uplevel do_eqp_test $args } do_execsql_test 1.1 { CREATE TABLE t1(a, b); CREATE INDEX i1 ON t1(a); CREATE INDEX i2 ON t1(b); CREATE TABLE t2(a, b); CREATE TABLE t3(a, b); } do_eqp_test 1.2 { SELECT * FROM t2, t1 WHERE t1.a=1 OR t1.b=2; } { 0 0 1 {SEARCH TABLE t1 USING INDEX i1 (a=?) (~10 rows)} 0 0 1 {SEARCH TABLE t1 USING INDEX i2 (b=?) (~10 rows)} 0 1 0 {SCAN TABLE t2 (~1000000 rows)} } do_eqp_test 1.3 { SELECT * FROM t2 CROSS JOIN t1 WHERE t1.a=1 OR t1.b=2; } { 0 0 0 {SCAN TABLE t2 (~1000000 rows)} 0 1 1 {SEARCH TABLE t1 USING INDEX i1 (a=?) (~10 rows)} 0 1 1 {SEARCH TABLE t1 USING INDEX i2 (b=?) (~10 rows)} } do_eqp_test 1.3 { SELECT a FROM t1 ORDER BY a } { 0 0 0 {SCAN TABLE t1 USING COVERING INDEX i1 (~1000000 rows)} } do_eqp_test 1.4 { SELECT a FROM t1 ORDER BY +a } { 0 0 0 {SCAN TABLE t1 (~1000000 rows)} 0 0 0 {USE TEMP B-TREE FOR ORDER BY} } do_eqp_test 1.5 { SELECT a FROM t1 WHERE a=4 } { 0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i1 (a=?) (~10 rows)} } do_eqp_test 1.6 { SELECT DISTINCT count(*) FROM t3 GROUP BY a; } { 0 0 0 {SCAN TABLE t3 (~1000000 rows)} 0 0 0 {USE TEMP B-TREE FOR GROUP BY} 0 0 0 {USE TEMP B-TREE FOR DISTINCT} } #------------------------------------------------------------------------- # Test cases eqp-2.* - tests for single select statements. # drop_all_tables do_execsql_test 2.1 { CREATE TABLE t1(x, y); CREATE TABLE t2(x, y); CREATE INDEX t2i1 ON t2(x); } det 2.2.1 "SELECT DISTINCT min(x), max(x) FROM t1 GROUP BY x ORDER BY 1" { 0 0 0 {SCAN TABLE t1 (~1000000 rows)} 0 0 0 {USE TEMP B-TREE FOR GROUP BY} 0 0 0 {USE TEMP B-TREE FOR DISTINCT} 0 0 0 {USE TEMP B-TREE FOR ORDER BY} } det 2.2.2 "SELECT DISTINCT min(x), max(x) FROM t2 GROUP BY x ORDER BY 1" { 0 0 0 {SCAN TABLE t2 USING COVERING INDEX t2i1 (~1000000 rows)} 0 0 0 {USE TEMP B-TREE FOR DISTINCT} 0 0 0 {USE TEMP B-TREE FOR ORDER BY} } det 2.2.3 "SELECT DISTINCT * FROM t1" { 0 0 0 {SCAN TABLE t1 (~1000000 rows)} 0 0 0 {USE TEMP B-TREE FOR DISTINCT} } det 2.2.4 "SELECT DISTINCT * FROM t1, t2" { 0 0 0 {SCAN TABLE t1 (~1000000 rows)} 0 1 1 {SCAN TABLE t2 (~1000000 rows)} 0 0 0 {USE TEMP B-TREE FOR DISTINCT} } det 2.2.5 "SELECT DISTINCT * FROM t1, t2 ORDER BY t1.x" { 0 0 0 {SCAN TABLE t1 (~1000000 rows)} 0 1 1 {SCAN TABLE t2 (~1000000 rows)} 0 0 0 {USE TEMP B-TREE FOR DISTINCT} 0 0 0 {USE TEMP B-TREE FOR ORDER BY} } det 2.2.6 "SELECT DISTINCT t2.x FROM t1, t2 ORDER BY t2.x" { 0 0 1 {SCAN TABLE t2 USING COVERING INDEX t2i1 (~1000000 rows)} 0 1 0 {SCAN TABLE t1 (~1000000 rows)} } det 2.3.1 "SELECT max(x) FROM t2" { 0 0 0 {SCAN TABLE t2 USING COVERING INDEX t2i1 (~1 rows)} } det 2.3.2 "SELECT min(x) FROM t2" { 0 0 0 {SCAN TABLE t2 USING COVERING INDEX t2i1 (~1 rows)} } det 2.3.3 "SELECT min(x), max(x) FROM t2" { 0 0 0 {SCAN TABLE t2 (~1000000 rows)} } det 2.4.1 "SELECT * FROM t1 WHERE rowid=?" { 0 0 0 {SEARCH TABLE t1 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)} } #------------------------------------------------------------------------- # Test cases eqp-3.* - tests for select statements that use sub-selects. # do_eqp_test 3.1.1 { SELECT (SELECT x FROM t1 AS sub) FROM t1; } { 0 0 0 {SCAN TABLE t1 (~1000000 rows)} 0 0 0 {EXECUTE SCALAR SUBQUERY 1} 1 0 0 {SCAN TABLE t1 AS sub (~1000000 rows)} } do_eqp_test 3.1.2 { SELECT * FROM t1 WHERE (SELECT x FROM t1 AS sub); } { 0 0 0 {SCAN TABLE t1 (~1000000 rows)} 0 0 0 {EXECUTE SCALAR SUBQUERY 1} 1 0 0 {SCAN TABLE t1 AS sub (~1000000 rows)} } do_eqp_test 3.1.3 { SELECT * FROM t1 WHERE (SELECT x FROM t1 AS sub ORDER BY y); } { 0 0 0 {SCAN TABLE t1 (~1000000 rows)} 0 0 0 {EXECUTE SCALAR SUBQUERY 1} 1 0 0 {SCAN TABLE t1 AS sub (~1000000 rows)} 1 0 0 {USE TEMP B-TREE FOR ORDER BY} } do_eqp_test 3.1.4 { SELECT * FROM t1 WHERE (SELECT x FROM t2 ORDER BY x); } { 0 0 0 {SCAN TABLE t1 (~1000000 rows)} 0 0 0 {EXECUTE SCALAR SUBQUERY 1} 1 0 0 {SCAN TABLE t2 USING COVERING INDEX t2i1 (~1000000 rows)} } det 3.2.1 { SELECT * FROM (SELECT * FROM t1 ORDER BY x LIMIT 10) ORDER BY y LIMIT 5 } { 1 0 0 {SCAN TABLE t1 (~1000000 rows)} 1 0 0 {USE TEMP B-TREE FOR ORDER BY} 0 0 0 {SCAN SUBQUERY 1 (~1000000 rows)} 0 0 0 {USE TEMP B-TREE FOR ORDER BY} } det 3.2.2 { SELECT * FROM (SELECT * FROM t1 ORDER BY x LIMIT 10) AS x1, (SELECT * FROM t2 ORDER BY x LIMIT 10) AS x2 ORDER BY x2.y LIMIT 5 } { 1 0 0 {SCAN TABLE t1 (~1000000 rows)} 1 0 0 {USE TEMP B-TREE FOR ORDER BY} 2 0 0 {SCAN TABLE t2 USING INDEX t2i1 (~1000000 rows)} 0 0 0 {SCAN SUBQUERY 1 AS x1 (~1000000 rows)} 0 1 1 {SCAN SUBQUERY 2 AS x2 (~1000000 rows)} 0 0 0 {USE TEMP B-TREE FOR ORDER BY} } det 3.3.1 { SELECT * FROM t1 WHERE y IN (SELECT y FROM t2) } { 0 0 0 {SCAN TABLE t1 (~100000 rows)} 0 0 0 {EXECUTE LIST SUBQUERY 1} 1 0 0 {SCAN TABLE t2 (~1000000 rows)} } det 3.3.2 { SELECT * FROM t1 WHERE y IN (SELECT y FROM t2 WHERE t1.x!=t2.x) } { 0 0 0 {SCAN TABLE t1 (~500000 rows)} 0 0 0 {EXECUTE CORRELATED LIST SUBQUERY 1} 1 0 0 {SCAN TABLE t2 (~500000 rows)} } det 3.3.3 { SELECT * FROM t1 WHERE EXISTS (SELECT y FROM t2 WHERE t1.x!=t2.x) } { 0 0 0 {SCAN TABLE t1 (~500000 rows)} 0 0 0 {EXECUTE CORRELATED SCALAR SUBQUERY 1} 1 0 0 {SCAN TABLE t2 (~500000 rows)} } #------------------------------------------------------------------------- # Test cases eqp-4.* - tests for composite select statements. # do_eqp_test 4.1.1 { SELECT * FROM t1 UNION ALL SELECT * FROM t2 } { 1 0 0 {SCAN TABLE t1 (~1000000 rows)} 2 0 0 {SCAN TABLE t2 (~1000000 rows)} 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (UNION ALL)} } do_eqp_test 4.1.2 { SELECT * FROM t1 UNION ALL SELECT * FROM t2 ORDER BY 2 } { 1 0 0 {SCAN TABLE t1 (~1000000 rows)} 1 0 0 {USE TEMP B-TREE FOR ORDER BY} 2 0 0 {SCAN TABLE t2 (~1000000 rows)} 2 0 0 {USE TEMP B-TREE FOR ORDER BY} 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (UNION ALL)} } do_eqp_test 4.1.3 { SELECT * FROM t1 UNION SELECT * FROM t2 ORDER BY 2 } { 1 0 0 {SCAN TABLE t1 (~1000000 rows)} 1 0 0 {USE TEMP B-TREE FOR ORDER BY} 2 0 0 {SCAN TABLE t2 (~1000000 rows)} 2 0 0 {USE TEMP B-TREE FOR ORDER BY} 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (UNION)} } do_eqp_test 4.1.4 { SELECT * FROM t1 INTERSECT SELECT * FROM t2 ORDER BY 2 } { 1 0 0 {SCAN TABLE t1 (~1000000 rows)} 1 0 0 {USE TEMP B-TREE FOR ORDER BY} 2 0 0 {SCAN TABLE t2 (~1000000 rows)} 2 0 0 {USE TEMP B-TREE FOR ORDER BY} 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (INTERSECT)} } do_eqp_test 4.1.5 { SELECT * FROM t1 EXCEPT SELECT * FROM t2 ORDER BY 2 } { 1 0 0 {SCAN TABLE t1 (~1000000 rows)} 1 0 0 {USE TEMP B-TREE FOR ORDER BY} 2 0 0 {SCAN TABLE t2 (~1000000 rows)} 2 0 0 {USE TEMP B-TREE FOR ORDER BY} 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (EXCEPT)} } do_eqp_test 4.2.2 { SELECT * FROM t1 UNION ALL SELECT * FROM t2 ORDER BY 1 } { 1 0 0 {SCAN TABLE t1 (~1000000 rows)} 1 0 0 {USE TEMP B-TREE FOR ORDER BY} 2 0 0 {SCAN TABLE t2 USING INDEX t2i1 (~1000000 rows)} 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (UNION ALL)} } do_eqp_test 4.2.3 { SELECT * FROM t1 UNION SELECT * FROM t2 ORDER BY 1 } { 1 0 0 {SCAN TABLE t1 (~1000000 rows)} 1 0 0 {USE TEMP B-TREE FOR ORDER BY} 2 0 0 {SCAN TABLE t2 (~1000000 rows)} 2 0 0 {USE TEMP B-TREE FOR ORDER BY} 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (UNION)} } do_eqp_test 4.2.4 { SELECT * FROM t1 INTERSECT SELECT * FROM t2 ORDER BY 1 } { 1 0 0 {SCAN TABLE t1 (~1000000 rows)} 1 0 0 {USE TEMP B-TREE FOR ORDER BY} 2 0 0 {SCAN TABLE t2 (~1000000 rows)} 2 0 0 {USE TEMP B-TREE FOR ORDER BY} 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (INTERSECT)} } do_eqp_test 4.2.5 { SELECT * FROM t1 EXCEPT SELECT * FROM t2 ORDER BY 1 } { 1 0 0 {SCAN TABLE t1 (~1000000 rows)} 1 0 0 {USE TEMP B-TREE FOR ORDER BY} 2 0 0 {SCAN TABLE t2 (~1000000 rows)} 2 0 0 {USE TEMP B-TREE FOR ORDER BY} 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (EXCEPT)} } do_eqp_test 4.3.1 { SELECT x FROM t1 UNION SELECT x FROM t2 } { 1 0 0 {SCAN TABLE t1 (~1000000 rows)} 2 0 0 {SCAN TABLE t2 (~1000000 rows)} 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 USING TEMP B-TREE (UNION)} } do_eqp_test 4.3.2 { SELECT x FROM t1 UNION SELECT x FROM t2 UNION SELECT x FROM t1 } { 2 0 0 {SCAN TABLE t1 (~1000000 rows)} 3 0 0 {SCAN TABLE t2 (~1000000 rows)} 1 0 0 {COMPOUND SUBQUERIES 2 AND 3 USING TEMP B-TREE (UNION)} 4 0 0 {SCAN TABLE t1 (~1000000 rows)} 0 0 0 {COMPOUND SUBQUERIES 1 AND 4 USING TEMP B-TREE (UNION)} } do_eqp_test 4.3.3 { SELECT x FROM t1 UNION SELECT x FROM t2 UNION SELECT x FROM t1 ORDER BY 1 } { 2 0 0 {SCAN TABLE t1 (~1000000 rows)} 2 0 0 {USE TEMP B-TREE FOR ORDER BY} 3 0 0 {SCAN TABLE t2 USING COVERING INDEX t2i1 (~1000000 rows)} 1 0 0 {COMPOUND SUBQUERIES 2 AND 3 (UNION)} 4 0 0 {SCAN TABLE t1 (~1000000 rows)} 4 0 0 {USE TEMP B-TREE FOR ORDER BY} 0 0 0 {COMPOUND SUBQUERIES 1 AND 4 (UNION)} } #------------------------------------------------------------------------- # This next block of tests verifies that the examples on the # lang_explain.html page are correct. # drop_all_tables # EVIDENCE-OF: R-64208-08323 sqlite> EXPLAIN QUERY PLAN SELECT a, b # FROM t1 WHERE a=1; 0|0|0|SCAN TABLE t1 (~100000 rows) do_execsql_test 5.1.0 { CREATE TABLE t1(a, b) } det 5.1.1 "SELECT a, b FROM t1 WHERE a=1" { 0 0 0 {SCAN TABLE t1 (~100000 rows)} } # EVIDENCE-OF: R-09022-44606 sqlite> CREATE INDEX i1 ON t1(a); # sqlite> EXPLAIN QUERY PLAN SELECT a, b FROM t1 WHERE a=1; # 0|0|0|SEARCH TABLE t1 USING INDEX i1 (a=?) (~10 rows) do_execsql_test 5.2.0 { CREATE INDEX i1 ON t1(a) } det 5.2.1 "SELECT a, b FROM t1 WHERE a=1" { 0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a=?) (~10 rows)} } # EVIDENCE-OF: R-62228-34103 sqlite> CREATE INDEX i2 ON t1(a, b); # sqlite> EXPLAIN QUERY PLAN SELECT a, b FROM t1 WHERE a=1; # 0|0|0|SEARCH TABLE t1 USING COVERING INDEX i2 (a=?) (~10 rows) do_execsql_test 5.3.0 { CREATE INDEX i2 ON t1(a, b) } det 5.3.1 "SELECT a, b FROM t1 WHERE a=1" { 0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i2 (a=?) (~10 rows)} } # EVIDENCE-OF: R-22253-05302 sqlite> EXPLAIN QUERY PLAN SELECT t1.*, # t2.* FROM t1, t2 WHERE t1.a=1 AND t1.b>2; 0|0|0|SEARCH TABLE t1 # USING COVERING INDEX i2 (a=? AND b>?) (~3 rows) 0|1|1|SCAN TABLE t2 # (~1000000 rows) do_execsql_test 5.4.0 {CREATE TABLE t2(c, d)} det 5.4.1 "SELECT t1.*, t2.* FROM t1, t2 WHERE t1.a=1 AND t1.b>2" { 0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i2 (a=? AND b>?) (~3 rows)} 0 1 1 {SCAN TABLE t2 (~1000000 rows)} } # EVIDENCE-OF: R-21040-07025 sqlite> EXPLAIN QUERY PLAN SELECT t1.*, # t2.* FROM t2, t1 WHERE t1.a=1 AND t1.b>2; 0|0|1|SEARCH TABLE t1 # USING COVERING INDEX i2 (a=? AND b>?) (~3 rows) 0|1|0|SCAN TABLE t2 # (~1000000 rows) det 5.5 "SELECT t1.*, t2.* FROM t2, t1 WHERE t1.a=1 AND t1.b>2" { 0 0 1 {SEARCH TABLE t1 USING COVERING INDEX i2 (a=? AND b>?) (~3 rows)} 0 1 0 {SCAN TABLE t2 (~1000000 rows)} } # EVIDENCE-OF: R-39007-61103 sqlite> CREATE INDEX i3 ON t1(b); # sqlite> EXPLAIN QUERY PLAN SELECT * FROM t1 WHERE a=1 OR b=2; # 0|0|0|SEARCH TABLE t1 USING COVERING INDEX i2 (a=?) (~10 rows) # 0|0|0|SEARCH TABLE t1 USING INDEX i3 (b=?) (~10 rows) do_execsql_test 5.5.0 {CREATE INDEX i3 ON t1(b)} det 5.6.1 "SELECT * FROM t1 WHERE a=1 OR b=2" { 0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i2 (a=?) (~10 rows)} 0 0 0 {SEARCH TABLE t1 USING INDEX i3 (b=?) (~10 rows)} } # EVIDENCE-OF: R-33025-54904 sqlite> EXPLAIN QUERY PLAN SELECT c, d # FROM t2 ORDER BY c; 0|0|0|SCAN TABLE t2 (~1000000 rows) 0|0|0|USE TEMP # B-TREE FOR ORDER BY det 5.7 "SELECT c, d FROM t2 ORDER BY c" { 0 0 0 {SCAN TABLE t2 (~1000000 rows)} 0 0 0 {USE TEMP B-TREE FOR ORDER BY} } # EVIDENCE-OF: R-38854-22809 sqlite> CREATE INDEX i4 ON t2(c); # sqlite> EXPLAIN QUERY PLAN SELECT c, d FROM t2 ORDER BY c; # 0|0|0|SCAN TABLE t2 USING INDEX i4 (~1000000 rows) do_execsql_test 5.8.0 {CREATE INDEX i4 ON t2(c)} det 5.8.1 "SELECT c, d FROM t2 ORDER BY c" { 0 0 0 {SCAN TABLE t2 USING INDEX i4 (~1000000 rows)} } # EVIDENCE-OF: R-29884-43993 sqlite> EXPLAIN QUERY PLAN SELECT # (SELECT b FROM t1 WHERE a=0), (SELECT a FROM t1 WHERE b=t2.c) FROM t2; # 0|0|0|SCAN TABLE t2 (~1000000 rows) 0|0|0|EXECUTE SCALAR SUBQUERY 1 # 1|0|0|SEARCH TABLE t1 USING COVERING INDEX i2 (a=?) (~10 rows) # 0|0|0|EXECUTE CORRELATED SCALAR SUBQUERY 2 2|0|0|SEARCH TABLE t1 USING # INDEX i3 (b=?) (~10 rows) det 5.9 { SELECT (SELECT b FROM t1 WHERE a=0), (SELECT a FROM t1 WHERE b=t2.c) FROM t2 } { 0 0 0 {SCAN TABLE t2 (~1000000 rows)} 0 0 0 {EXECUTE SCALAR SUBQUERY 1} 1 0 0 {SEARCH TABLE t1 USING COVERING INDEX i2 (a=?) (~10 rows)} 0 0 0 {EXECUTE CORRELATED SCALAR SUBQUERY 2} 2 0 0 {SEARCH TABLE t1 USING INDEX i3 (b=?) (~10 rows)} } # EVIDENCE-OF: R-17911-16445 sqlite> EXPLAIN QUERY PLAN SELECT # count(*) FROM (SELECT max(b) AS x FROM t1 GROUP BY a) GROUP BY x; # 1|0|0|SCAN TABLE t1 USING COVERING INDEX i2 (~1000000 rows) 0|0|0|SCAN # SUBQUERY 1 (~1000000 rows) 0|0|0|USE TEMP B-TREE FOR GROUP BY det 5.10 { SELECT count(*) FROM (SELECT max(b) AS x FROM t1 GROUP BY a) GROUP BY x } { 1 0 0 {SCAN TABLE t1 USING COVERING INDEX i2 (~1000000 rows)} 0 0 0 {SCAN SUBQUERY 1 (~1000000 rows)} 0 0 0 {USE TEMP B-TREE FOR GROUP BY} } # EVIDENCE-OF: R-18544-33103 sqlite> EXPLAIN QUERY PLAN SELECT * FROM # (SELECT * FROM t2 WHERE c=1), t1; 0|0|0|SEARCH TABLE t2 USING INDEX i4 # (c=?) (~10 rows) 0|1|1|SCAN TABLE t1 (~1000000 rows) det 5.11 "SELECT * FROM (SELECT * FROM t2 WHERE c=1), t1" { 0 0 0 {SEARCH TABLE t2 USING INDEX i4 (c=?) (~10 rows)} 0 1 1 {SCAN TABLE t1 (~1000000 rows)} } # EVIDENCE-OF: R-40701-42164 sqlite> EXPLAIN QUERY PLAN SELECT a FROM # t1 UNION SELECT c FROM t2; 1|0|0|SCAN TABLE t1 (~1000000 rows) # 2|0|0|SCAN TABLE t2 (~1000000 rows) 0|0|0|COMPOUND SUBQUERIES 1 AND 2 # USING TEMP B-TREE (UNION) det 5.12 "SELECT a FROM t1 UNION SELECT c FROM t2" { 1 0 0 {SCAN TABLE t1 (~1000000 rows)} 2 0 0 {SCAN TABLE t2 (~1000000 rows)} 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 USING TEMP B-TREE (UNION)} } # EVIDENCE-OF: R-61538-24748 sqlite> EXPLAIN QUERY PLAN SELECT a FROM # t1 EXCEPT SELECT d FROM t2 ORDER BY 1; 1|0|0|SCAN TABLE t1 USING # COVERING INDEX i2 (~1000000 rows) 2|0|0|SCAN TABLE t2 (~1000000 rows) # 2|0|0|USE TEMP B-TREE FOR ORDER BY 0|0|0|COMPOUND SUBQUERIES 1 AND 2 # (EXCEPT) det 5.13 "SELECT a FROM t1 EXCEPT SELECT d FROM t2 ORDER BY 1" { 1 0 0 {SCAN TABLE t1 USING COVERING INDEX i2 (~1000000 rows)} 2 0 0 {SCAN TABLE t2 (~1000000 rows)} 2 0 0 {USE TEMP B-TREE FOR ORDER BY} 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (EXCEPT)} } finish_test |
Changes to test/fts3fault.test.
︙ | ︙ | |||
10 11 12 13 14 15 16 17 18 19 20 21 22 23 | #*********************************************************************** # set testdir [file dirname $argv0] source $testdir/tester.tcl set ::testprefix fts3fault # Test error handling in the sqlite3Fts3Init() function. This is the # function that registers the FTS3 module and various support functions # with SQLite. # do_faultsim_test 1 -body { sqlite3 db test.db | > > > | 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 | #*********************************************************************** # set testdir [file dirname $argv0] source $testdir/tester.tcl set ::testprefix fts3fault # If SQLITE_ENABLE_FTS3 is not defined, omit this file. ifcapable !fts3 { finish_test ; return } # Test error handling in the sqlite3Fts3Init() function. This is the # function that registers the FTS3 module and various support functions # with SQLite. # do_faultsim_test 1 -body { sqlite3 db test.db |
︙ | ︙ |
Changes to test/fts3matchinfo.test.
︙ | ︙ | |||
10 11 12 13 14 15 16 17 18 19 20 21 22 23 | #*********************************************************************** # This file implements regression tests for the FTS3 module. The focus # of this file is tables created with the "matchinfo=fts3" option. # set testdir [file dirname $argv0] source $testdir/tester.tcl set testprefix fts3matchinfo proc mit {blob} { set scan(littleEndian) i* set scan(bigEndian) I* binary scan $blob $scan($::tcl_platform(byteOrder)) r | > > > | 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 | #*********************************************************************** # This file implements regression tests for the FTS3 module. The focus # of this file is tables created with the "matchinfo=fts3" option. # set testdir [file dirname $argv0] source $testdir/tester.tcl # If SQLITE_ENABLE_FTS3 is not defined, omit this file. ifcapable !fts3 { finish_test ; return } set testprefix fts3matchinfo proc mit {blob} { set scan(littleEndian) i* set scan(bigEndian) I* binary scan $blob $scan($::tcl_platform(byteOrder)) r |
︙ | ︙ |
Changes to test/indexedby.test.
︙ | ︙ | |||
36 37 38 39 40 41 42 | # proc EQP {sql} { uplevel "execsql {EXPLAIN QUERY PLAN $sql}" } # These tests are to check that "EXPLAIN QUERY PLAN" is working as expected. # | | | | | | | | | > > | > | 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 | # proc EQP {sql} { uplevel "execsql {EXPLAIN QUERY PLAN $sql}" } # These tests are to check that "EXPLAIN QUERY PLAN" is working as expected. # do_execsql_test indexedby-1.2 { EXPLAIN QUERY PLAN select * from t1 WHERE a = 10; } {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a=?) (~10 rows)}} do_execsql_test indexedby-1.3 { EXPLAIN QUERY PLAN select * from t1 ; } {0 0 0 {SCAN TABLE t1 (~1000000 rows)}} do_execsql_test indexedby-1.4 { EXPLAIN QUERY PLAN select * from t1, t2 WHERE c = 10; } { 0 0 1 {SEARCH TABLE t2 USING INDEX i3 (c=?) (~10 rows)} 0 1 0 {SCAN TABLE t1 (~1000000 rows)} } # Parser tests. Test that an INDEXED BY or NOT INDEX clause can be # attached to a table in the FROM clause, but not to a sub-select or # SQL view. Also test that specifying an index that does not exist or # is attached to a different table is detected as an error. # do_test indexedby-2.1 { |
︙ | ︙ | |||
76 77 78 79 80 81 82 | } {1 {near "WHERE": syntax error}} do_test indexedby-2.7 { catchsql { SELECT * FROM v1 INDEXED BY i1 WHERE a = 'one' } } {1 {no such index: i1}} # Tests for single table cases. # | | | | | > | | | > | | | > | | | > | | | | > | > > | | > | > > | < | < | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | > | | | > | | | 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 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 | } {1 {near "WHERE": syntax error}} do_test indexedby-2.7 { catchsql { SELECT * FROM v1 INDEXED BY i1 WHERE a = 'one' } } {1 {no such index: i1}} # Tests for single table cases. # do_execsql_test indexedby-3.1 { EXPLAIN QUERY PLAN SELECT * FROM t1 NOT INDEXED WHERE a = 'one' AND b = 'two' } {0 0 0 {SCAN TABLE t1 (~10000 rows)}} do_execsql_test indexedby-3.2 { EXPLAIN QUERY PLAN SELECT * FROM t1 INDEXED BY i1 WHERE a = 'one' AND b = 'two' } {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a=?) (~2 rows)}} do_execsql_test indexedby-3.3 { EXPLAIN QUERY PLAN SELECT * FROM t1 INDEXED BY i2 WHERE a = 'one' AND b = 'two' } {0 0 0 {SEARCH TABLE t1 USING INDEX i2 (b=?) (~2 rows)}} do_test indexedby-3.4 { catchsql { SELECT * FROM t1 INDEXED BY i2 WHERE a = 'one' } } {1 {cannot use index: i2}} do_test indexedby-3.5 { catchsql { SELECT * FROM t1 INDEXED BY i2 ORDER BY a } } {1 {cannot use index: i2}} do_test indexedby-3.6 { catchsql { SELECT * FROM t1 INDEXED BY i1 WHERE a = 'one' } } {0 {}} do_test indexedby-3.7 { catchsql { SELECT * FROM t1 INDEXED BY i1 ORDER BY a } } {0 {}} do_execsql_test indexedby-3.8 { EXPLAIN QUERY PLAN SELECT * FROM t3 INDEXED BY sqlite_autoindex_t3_1 ORDER BY e } {0 0 0 {SCAN TABLE t3 USING INDEX sqlite_autoindex_t3_1 (~1000000 rows)}} do_execsql_test indexedby-3.9 { EXPLAIN QUERY PLAN SELECT * FROM t3 INDEXED BY sqlite_autoindex_t3_1 WHERE e = 10 } {0 0 0 {SEARCH TABLE t3 USING INDEX sqlite_autoindex_t3_1 (e=?) (~1 rows)}} do_test indexedby-3.10 { catchsql { SELECT * FROM t3 INDEXED BY sqlite_autoindex_t3_1 WHERE f = 10 } } {1 {cannot use index: sqlite_autoindex_t3_1}} do_test indexedby-3.11 { catchsql { SELECT * FROM t3 INDEXED BY sqlite_autoindex_t3_2 WHERE f = 10 } } {1 {no such index: sqlite_autoindex_t3_2}} # Tests for multiple table cases. # do_execsql_test indexedby-4.1 { EXPLAIN QUERY PLAN SELECT * FROM t1, t2 WHERE a = c } { 0 0 0 {SCAN TABLE t1 (~1000000 rows)} 0 1 1 {SEARCH TABLE t2 USING INDEX i3 (c=?) (~10 rows)} } do_execsql_test indexedby-4.2 { EXPLAIN QUERY PLAN SELECT * FROM t1 INDEXED BY i1, t2 WHERE a = c } { 0 0 1 {SCAN TABLE t2 (~1000000 rows)} 0 1 0 {SEARCH TABLE t1 USING INDEX i1 (a=?) (~10 rows)} } do_test indexedby-4.3 { catchsql { SELECT * FROM t1 INDEXED BY i1, t2 INDEXED BY i3 WHERE a=c } } {1 {cannot use index: i1}} do_test indexedby-4.4 { catchsql { SELECT * FROM t2 INDEXED BY i3, t1 INDEXED BY i1 WHERE a=c } } {1 {cannot use index: i3}} # Test embedding an INDEXED BY in a CREATE VIEW statement. This block # also tests that nothing bad happens if an index refered to by # a CREATE VIEW statement is dropped and recreated. # do_execsql_test indexedby-5.1 { CREATE VIEW v2 AS SELECT * FROM t1 INDEXED BY i1 WHERE a > 5; EXPLAIN QUERY PLAN SELECT * FROM v2 } {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a>?) (~330000 rows)}} do_execsql_test indexedby-5.2 { EXPLAIN QUERY PLAN SELECT * FROM v2 WHERE b = 10 } {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a>?) (~33000 rows)}} do_test indexedby-5.3 { execsql { DROP INDEX i1 } catchsql { SELECT * FROM v2 } } {1 {no such index: i1}} do_test indexedby-5.4 { # Recreate index i1 in such a way as it cannot be used by the view query. execsql { CREATE INDEX i1 ON t1(b) } catchsql { SELECT * FROM v2 } } {1 {cannot use index: i1}} do_test indexedby-5.5 { # Drop and recreate index i1 again. This time, create it so that it can # be used by the query. execsql { DROP INDEX i1 ; CREATE INDEX i1 ON t1(a) } catchsql { SELECT * FROM v2 } } {0 {}} # Test that "NOT INDEXED" may use the rowid index, but not others. # do_execsql_test indexedby-6.1 { EXPLAIN QUERY PLAN SELECT * FROM t1 WHERE b = 10 ORDER BY rowid } {0 0 0 {SEARCH TABLE t1 USING INDEX i2 (b=?) (~10 rows)}} do_execsql_test indexedby-6.2 { EXPLAIN QUERY PLAN SELECT * FROM t1 NOT INDEXED WHERE b = 10 ORDER BY rowid } {0 0 0 {SCAN TABLE t1 USING INTEGER PRIMARY KEY (~100000 rows)}} # Test that "INDEXED BY" can be used in a DELETE statement. # do_execsql_test indexedby-7.1 { EXPLAIN QUERY PLAN DELETE FROM t1 WHERE a = 5 } {0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i1 (a=?) (~10 rows)}} do_execsql_test indexedby-7.2 { EXPLAIN QUERY PLAN DELETE FROM t1 NOT INDEXED WHERE a = 5 } {0 0 0 {SCAN TABLE t1 (~100000 rows)}} do_execsql_test indexedby-7.3 { EXPLAIN QUERY PLAN DELETE FROM t1 INDEXED BY i1 WHERE a = 5 } {0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i1 (a=?) (~10 rows)}} do_execsql_test indexedby-7.4 { EXPLAIN QUERY PLAN DELETE FROM t1 INDEXED BY i1 WHERE a = 5 AND b = 10 } {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a=?) (~2 rows)}} do_execsql_test indexedby-7.5 { EXPLAIN QUERY PLAN DELETE FROM t1 INDEXED BY i2 WHERE a = 5 AND b = 10 } {0 0 0 {SEARCH TABLE t1 USING INDEX i2 (b=?) (~2 rows)}} do_test indexedby-7.6 { catchsql { DELETE FROM t1 INDEXED BY i2 WHERE a = 5} } {1 {cannot use index: i2}} # Test that "INDEXED BY" can be used in an UPDATE statement. # do_execsql_test indexedby-8.1 { EXPLAIN QUERY PLAN UPDATE t1 SET rowid=rowid+1 WHERE a = 5 } {0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i1 (a=?) (~10 rows)}} do_execsql_test indexedby-8.2 { EXPLAIN QUERY PLAN UPDATE t1 NOT INDEXED SET rowid=rowid+1 WHERE a = 5 } {0 0 0 {SCAN TABLE t1 (~100000 rows)}} do_execsql_test indexedby-8.3 { EXPLAIN QUERY PLAN UPDATE t1 INDEXED BY i1 SET rowid=rowid+1 WHERE a = 5 } {0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i1 (a=?) (~10 rows)}} do_execsql_test indexedby-8.4 { EXPLAIN QUERY PLAN UPDATE t1 INDEXED BY i1 SET rowid=rowid+1 WHERE a = 5 AND b = 10 } {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a=?) (~2 rows)}} do_execsql_test indexedby-8.5 { EXPLAIN QUERY PLAN UPDATE t1 INDEXED BY i2 SET rowid=rowid+1 WHERE a = 5 AND b = 10 } {0 0 0 {SEARCH TABLE t1 USING INDEX i2 (b=?) (~2 rows)}} do_test indexedby-8.6 { catchsql { UPDATE t1 INDEXED BY i2 SET rowid=rowid+1 WHERE a = 5} } {1 {cannot use index: i2}} # Test that bug #3560 is fixed. # do_test indexedby-9.1 { |
︙ | ︙ |
Changes to test/tester.tcl.
︙ | ︙ | |||
345 346 347 348 349 350 351 | } { set testname "${::testprefix}-$testname" } } proc do_execsql_test {testname sql {result {}}} { fix_testname testname | | | 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 | } { set testname "${::testprefix}-$testname" } } proc do_execsql_test {testname sql {result {}}} { fix_testname testname uplevel do_test $testname [list "execsql {$sql}"] [list [list {*}$result]] } proc do_catchsql_test {testname sql result} { fix_testname testname uplevel do_test $testname [list "catchsql {$sql}"] [list $result] } #------------------------------------------------------------------------- |
︙ | ︙ |
Changes to test/tkt-78e04e52ea.test.
︙ | ︙ | |||
40 41 42 43 44 45 46 | CREATE INDEX i1 ON ""("" COLLATE nocase); } } {} do_test tkt-78e04-1.4 { execsql { EXPLAIN QUERY PLAN SELECT * FROM "" WHERE "" LIKE 'abc%'; } | | | | | 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 | CREATE INDEX i1 ON ""("" COLLATE nocase); } } {} do_test tkt-78e04-1.4 { execsql { EXPLAIN QUERY PLAN SELECT * FROM "" WHERE "" LIKE 'abc%'; } } {0 0 0 {SCAN TABLE (~500000 rows)}} do_test tkt-78e04-1.5 { execsql { DROP TABLE ""; SELECT name FROM sqlite_master; } } {t2} do_test tkt-78e04-2.1 { execsql { CREATE INDEX "" ON t2(x); EXPLAIN QUERY PLAN SELECT * FROM t2 WHERE x=5; } } {0 0 0 {SEARCH TABLE t2 USING COVERING INDEX (x=?) (~10 rows)}} do_test tkt-78e04-2.2 { execsql { DROP INDEX ""; EXPLAIN QUERY PLAN SELECT * FROM t2 WHERE x=2; } } {0 0 0 {SCAN TABLE t2 (~100000 rows)}} finish_test |
Changes to test/tkt3442.test.
︙ | ︙ | |||
45 46 47 48 49 50 51 | # These tests perform an EXPLAIN QUERY PLAN on both versions of the # SELECT referenced in ticket #3442 (both '5000' and "5000") # and verify that the query plan is the same. # ifcapable explain { do_test tkt3442-1.2 { EQP { SELECT node FROM listhash WHERE id='5000' LIMIT 1; } | | | | | 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 | # These tests perform an EXPLAIN QUERY PLAN on both versions of the # SELECT referenced in ticket #3442 (both '5000' and "5000") # and verify that the query plan is the same. # ifcapable explain { do_test tkt3442-1.2 { EQP { SELECT node FROM listhash WHERE id='5000' LIMIT 1; } } {0 0 0 {SEARCH TABLE listhash USING INDEX ididx (id=?) (~1 rows)}} do_test tkt3442-1.3 { EQP { SELECT node FROM listhash WHERE id="5000" LIMIT 1; } } {0 0 0 {SEARCH TABLE listhash USING INDEX ididx (id=?) (~1 rows)}} } # Some extra tests testing other permutations of 5000. # ifcapable explain { do_test tkt3442-1.4 { EQP { SELECT node FROM listhash WHERE id=5000 LIMIT 1; } } {0 0 0 {SEARCH TABLE listhash USING INDEX ididx (id=?) (~1 rows)}} } do_test tkt3442-1.5 { catchsql { SELECT node FROM listhash WHERE id=[5000] LIMIT 1; } } {1 {no such column: 5000}} |
︙ | ︙ |
Changes to test/where3.test.
︙ | ︙ | |||
213 214 215 216 217 218 219 | } {tB {} tC * tA * tD *} # Ticket [13f033c865f878953] # If the outer loop must be a full table scan, do not let ANALYZE trick # the planner into use a table for the outer loop that might be indexable # if held until an inner loop. # | | < | | | | | < | > > > | < | < | | > > > | < | < | | | | | > > > > | < | < | | > > > > | < | < | | > > > > | < | < | | | | | | | | | | | | | | | | | < < | | | | | | | > > > > | < | < | | | | | | | > > > > | < | < | | | | | | | > > > > | < | < | | | | | | | > > > > | < | 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 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 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 | } {tB {} tC * tA * tD *} # Ticket [13f033c865f878953] # If the outer loop must be a full table scan, do not let ANALYZE trick # the planner into use a table for the outer loop that might be indexable # if held until an inner loop. # do_execsql_test where3-3.0 { CREATE TABLE t301(a INTEGER PRIMARY KEY,b,c); CREATE INDEX t301c ON t301(c); INSERT INTO t301 VALUES(1,2,3); CREATE TABLE t302(x, y); ANALYZE; explain query plan SELECT * FROM t302, t301 WHERE t302.x=5 AND t301.a=t302.y; } { 0 0 0 {SCAN TABLE t302 (~0 rows)} 0 1 1 {SEARCH TABLE t301 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)} } do_execsql_test where3-3.1 { explain query plan SELECT * FROM t301, t302 WHERE t302.x=5 AND t301.a=t302.y; } { 0 0 1 {SCAN TABLE t302 (~0 rows)} 0 1 0 {SEARCH TABLE t301 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)} } # Verify that when there are multiple tables in a join which must be # full table scans that the query planner attempts put the table with # the fewest number of output rows as the outer loop. # do_execsql_test where3-4.0 { CREATE TABLE t400(a INTEGER PRIMARY KEY, b, c); CREATE TABLE t401(p INTEGER PRIMARY KEY, q, r); CREATE TABLE t402(x INTEGER PRIMARY KEY, y, z); EXPLAIN QUERY PLAN SELECT * FROM t400, t401, t402 WHERE t402.z GLOB 'abc*'; } { 0 0 2 {SCAN TABLE t402 (~500000 rows)} 0 1 0 {SCAN TABLE t400 (~1000000 rows)} 0 2 1 {SCAN TABLE t401 (~1000000 rows)} } do_execsql_test where3-4.1 { EXPLAIN QUERY PLAN SELECT * FROM t400, t401, t402 WHERE t401.r GLOB 'abc*'; } { 0 0 1 {SCAN TABLE t401 (~500000 rows)} 0 1 0 {SCAN TABLE t400 (~1000000 rows)} 0 2 2 {SCAN TABLE t402 (~1000000 rows)} } do_execsql_test where3-4.2 { EXPLAIN QUERY PLAN SELECT * FROM t400, t401, t402 WHERE t400.c GLOB 'abc*'; } { 0 0 0 {SCAN TABLE t400 (~500000 rows)} 0 1 1 {SCAN TABLE t401 (~1000000 rows)} 0 2 2 {SCAN TABLE t402 (~1000000 rows)} } # Verify that a performance regression encountered by firefox # has been fixed. # do_execsql_test where3-5.0 { CREATE TABLE aaa (id INTEGER PRIMARY KEY, type INTEGER, fk INTEGER DEFAULT NULL, parent INTEGER, position INTEGER, title LONGVARCHAR, keyword_id INTEGER, folder_type TEXT, dateAdded INTEGER, lastModified INTEGER); CREATE INDEX aaa_111 ON aaa (fk, type); CREATE INDEX aaa_222 ON aaa (parent, position); CREATE INDEX aaa_333 ON aaa (fk, lastModified); CREATE TABLE bbb (id INTEGER PRIMARY KEY, type INTEGER, fk INTEGER DEFAULT NULL, parent INTEGER, position INTEGER, title LONGVARCHAR, keyword_id INTEGER, folder_type TEXT, dateAdded INTEGER, lastModified INTEGER); CREATE INDEX bbb_111 ON bbb (fk, type); CREATE INDEX bbb_222 ON bbb (parent, position); CREATE INDEX bbb_333 ON bbb (fk, lastModified); EXPLAIN QUERY PLAN SELECT bbb.title AS tag_title FROM aaa JOIN bbb ON bbb.id = aaa.parent WHERE aaa.fk = 'constant' AND LENGTH(bbb.title) > 0 AND bbb.parent = 4 ORDER BY bbb.title COLLATE NOCASE ASC; } { 0 0 0 {SEARCH TABLE aaa USING INDEX aaa_333 (fk=?) (~10 rows)} 0 1 1 {SEARCH TABLE bbb USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)} 0 0 0 {USE TEMP B-TREE FOR ORDER BY} } do_execsql_test where3-5.1 { EXPLAIN QUERY PLAN SELECT bbb.title AS tag_title FROM aaa JOIN aaa AS bbb ON bbb.id = aaa.parent WHERE aaa.fk = 'constant' AND LENGTH(bbb.title) > 0 AND bbb.parent = 4 ORDER BY bbb.title COLLATE NOCASE ASC; } { 0 0 0 {SEARCH TABLE aaa USING INDEX aaa_333 (fk=?) (~10 rows)} 0 1 1 {SEARCH TABLE aaa AS bbb USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)} 0 0 0 {USE TEMP B-TREE FOR ORDER BY} } do_execsql_test where3-5.2 { EXPLAIN QUERY PLAN SELECT bbb.title AS tag_title FROM bbb JOIN aaa ON bbb.id = aaa.parent WHERE aaa.fk = 'constant' AND LENGTH(bbb.title) > 0 AND bbb.parent = 4 ORDER BY bbb.title COLLATE NOCASE ASC; } { 0 0 1 {SEARCH TABLE aaa USING INDEX aaa_333 (fk=?) (~10 rows)} 0 1 0 {SEARCH TABLE bbb USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)} 0 0 0 {USE TEMP B-TREE FOR ORDER BY} } do_execsql_test where3-5.3 { EXPLAIN QUERY PLAN SELECT bbb.title AS tag_title FROM aaa AS bbb JOIN aaa ON bbb.id = aaa.parent WHERE aaa.fk = 'constant' AND LENGTH(bbb.title) > 0 AND bbb.parent = 4 ORDER BY bbb.title COLLATE NOCASE ASC; } { 0 0 1 {SEARCH TABLE aaa USING INDEX aaa_333 (fk=?) (~10 rows)} 0 1 0 {SEARCH TABLE aaa AS bbb USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)} 0 0 0 {USE TEMP B-TREE FOR ORDER BY} } finish_test |
Changes to test/where7.test.
︙ | ︙ | |||
23303 23304 23305 23306 23307 23308 23309 | # test case for the performance regression fixed by # check-in 28ba6255282b on 2010-10-21 02:05:06 # # The test case that follows is code from an actual # application with identifiers change and unused columns # remove. # | | < | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | | > > > > > | < | 23303 23304 23305 23306 23307 23308 23309 23310 23311 23312 23313 23314 23315 23316 23317 23318 23319 23320 23321 23322 23323 23324 23325 23326 23327 23328 23329 23330 23331 23332 23333 23334 23335 23336 23337 23338 23339 23340 23341 23342 23343 23344 23345 23346 23347 23348 23349 23350 | # test case for the performance regression fixed by # check-in 28ba6255282b on 2010-10-21 02:05:06 # # The test case that follows is code from an actual # application with identifiers change and unused columns # remove. # do_execsql_test where7-3.1 { CREATE TABLE t301 ( c8 INTEGER PRIMARY KEY, c6 INTEGER, c4 INTEGER, c7 INTEGER, FOREIGN KEY (c4) REFERENCES series(c4) ); CREATE INDEX t301_c6 on t301(c6); CREATE INDEX t301_c4 on t301(c4); CREATE INDEX t301_c7 on t301(c7); CREATE TABLE t302 ( c1 INTEGER PRIMARY KEY, c8 INTEGER, c5 INTEGER, c3 INTEGER, c2 INTEGER, c4 INTEGER, FOREIGN KEY (c8) REFERENCES t301(c8) ); CREATE INDEX t302_c3 on t302(c3); CREATE INDEX t302_c8_c3 on t302(c8, c3); CREATE INDEX t302_c5 on t302(c5); EXPLAIN QUERY PLAN SELECT t302.c1 FROM t302 JOIN t301 ON t302.c8 = t301.c8 WHERE t302.c2 = 19571 AND t302.c3 > 1287603136 AND (t301.c4 = 1407449685622784 OR t301.c8 = 1407424651264000) ORDER BY t302.c5 LIMIT 200; } { 0 0 1 {SEARCH TABLE t301 USING COVERING INDEX t301_c4 (c4=?) (~10 rows)} 0 0 1 {SEARCH TABLE t301 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)} 0 1 0 {SEARCH TABLE t302 USING INDEX t302_c8_c3 (c8=? AND c3>?) (~2 rows)} 0 0 0 {USE TEMP B-TREE FOR ORDER BY} } finish_test |
Changes to test/where9.test.
︙ | ︙ | |||
354 355 356 357 358 359 360 | WHERE t1.a=t3.y OR t1.b=t3.y*11 OR (t1.c=27027 AND round(t1.d)==80) ORDER BY 1, 2, 3 } } {1 80 2 1 80 28 1 80 54 1 80 80 2 80 2 2 80 28 2 80 54 2 80 80 scan 1 sort 1} ifcapable explain { | | < | | < | | | | < | < < > | < | | | | | | | < | < < > | 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 | WHERE t1.a=t3.y OR t1.b=t3.y*11 OR (t1.c=27027 AND round(t1.d)==80) ORDER BY 1, 2, 3 } } {1 80 2 1 80 28 1 80 54 1 80 80 2 80 2 2 80 28 2 80 54 2 80 80 scan 1 sort 1} ifcapable explain { do_execsql_test where9-3.1 { EXPLAIN QUERY PLAN SELECT t2.a FROM t1, t2 WHERE t1.a=80 AND ((t1.c=t2.c AND t1.d=t2.d) OR t1.f=t2.f) } { 0 0 0 {SEARCH TABLE t1 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)} 0 1 1 {SEARCH TABLE t2 USING INDEX t2d (d=?) (~2 rows)} 0 1 1 {SEARCH TABLE t2 USING COVERING INDEX t2f (f=?) (~10 rows)} } do_execsql_test where9-3.2 { EXPLAIN QUERY PLAN SELECT coalesce(t2.a,9999) FROM t1 LEFT JOIN t2 ON (t1.c+1=t2.c AND t1.d=t2.d) OR (t1.f||'x')=t2.f WHERE t1.a=80 } { 0 0 0 {SEARCH TABLE t1 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)} 0 1 1 {SEARCH TABLE t2 USING INDEX t2d (d=?) (~2 rows)} 0 1 1 {SEARCH TABLE t2 USING COVERING INDEX t2f (f=?) (~10 rows)} } } # Make sure that INDEXED BY and multi-index OR clauses play well with # one another. # do_test where9-4.1 { count_steps { |
︙ | ︙ | |||
454 455 456 457 458 459 460 | } } {1 {cannot use index: t1d}} ifcapable explain { # The (c=31031 OR d IS NULL) clause is preferred over b>1000 because # the former is an equality test which is expected to return fewer rows. # | | < | < < < | | | < < | > | < | < < < | < | < < | > | < | < < < | | < < < > | 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 | } } {1 {cannot use index: t1d}} ifcapable explain { # The (c=31031 OR d IS NULL) clause is preferred over b>1000 because # the former is an equality test which is expected to return fewer rows. # do_execsql_test where9-5.1 { EXPLAIN QUERY PLAN SELECT a FROM t1 WHERE b>1000 AND (c=31031 OR d IS NULL) } { 0 0 0 {SEARCH TABLE t1 USING INDEX t1c (c=?) (~10 rows)} 0 0 0 {SEARCH TABLE t1 USING INDEX t1d (d=?) (~10 rows)} } # In contrast, b=1000 is preferred over any OR-clause. # do_execsql_test where9-5.2 { EXPLAIN QUERY PLAN SELECT a FROM t1 WHERE b=1000 AND (c=31031 OR d IS NULL) } { 0 0 0 {SEARCH TABLE t1 USING INDEX t1b (b=?) (~5 rows)} } # Likewise, inequalities in an AND are preferred over inequalities in # an OR. # do_execsql_test where9-5.3 { EXPLAIN QUERY PLAN SELECT a FROM t1 WHERE b>1000 AND (c>=31031 OR d IS NULL) } { 0 0 0 {SEARCH TABLE t1 USING INDEX t1b (b>?) (~165000 rows)} } } ############################################################################ # Make sure OR-clauses work correctly on UPDATE and DELETE statements. do_test where9-6.2.1 { db eval {SELECT count(*) FROM t1 UNION ALL SELECT a FROM t1 WHERE a>=85} |
︙ | ︙ |