mirror of
https://github.com/sqlite/sqlite.git
synced 2025-11-11 01:42:22 +03:00
Improvements to distinct aggregates such that they can sometimes avoid
using an ephermeral table to test for duplicates if the column that is distinct is part of an index. FossilOrigin-Name: ef4ac0ddd297bbd38351410c5a387e1628561b3f1bec9e4c2c9d76fbe29f955a
This commit is contained in:
19
manifest
19
manifest
@@ -1,5 +1,5 @@
|
||||
C Fix\sa\sharmless\scompiler\swarning.
|
||||
D 2021-03-24T17:04:32.761
|
||||
C Improvements\sto\sdistinct\saggregates\ssuch\sthat\sthey\scan\ssometimes\savoid\nusing\san\sephermeral\stable\sto\stest\sfor\sduplicates\sif\sthe\scolumn\sthat\sis\ndistinct\sis\spart\sof\san\sindex.
|
||||
D 2021-03-24T17:28:11.642
|
||||
F .fossil-settings/empty-dirs dbb81e8fc0401ac46a1491ab34a7f2c7c0452f2f06b54ebb845d024ca8283ef1
|
||||
F .fossil-settings/ignore-glob 35175cdfcf539b2318cb04a9901442804be81cd677d8b889fcc9149c21f239ea
|
||||
F LICENSE.md df5091916dbb40e6e9686186587125e1b2ff51f022cc334e886c19a0e9982724
|
||||
@@ -542,12 +542,12 @@ F src/printf.c 78fabb49b9ac9a12dd1c89d744abdc9b67fd3205e62967e158f78b965a29ec4b
|
||||
F src/random.c 80f5d666f23feb3e6665a6ce04c7197212a88384
|
||||
F src/resolve.c d95db73d3e6a5c689e5f6604b4d2521350e45f2a0f0f84f5a2dc2bfee56580a0
|
||||
F src/rowset.c ba9515a922af32abe1f7d39406b9d35730ed65efab9443dc5702693b60854c92
|
||||
F src/select.c fe0a11d7cf2eddd58cf6fc5f65a5faac1eb430102a3f00092673a499bfd4a50e
|
||||
F src/select.c 9109ca4a3179eb46770e10c04f01fd226751ccf0caeea8db58000e3371f9fa21
|
||||
F src/shell.c.in dcce260883836c9b58847505fbccce8d5546af925046f7dacd9443e922ece036
|
||||
F src/sqlite.h.in 3426a080ea1f222a73e3bd91e7eacbd30570a0117c03d42c6dde606f33e5e318
|
||||
F src/sqlite3.rc 5121c9e10c3964d5755191c80dd1180c122fc3a8
|
||||
F src/sqlite3ext.h 61b38c073d5e1e96a3d45271b257aef27d0d13da2bea5347692ae579475cd95e
|
||||
F src/sqliteInt.h 0f6446f61254d21a398900b888f0fe30179b24f87dde42acf94e767a99888c0b
|
||||
F src/sqliteInt.h 87bb2f645fcd6f2b7dbf41f85777d3c24a4b08e73c7153741cdd0481e9ab213d
|
||||
F src/sqliteLimit.h d7323ffea5208c6af2734574bae933ca8ed2ab728083caa117c9738581a31657
|
||||
F src/status.c 4b8bc2a6905163a38b739854a35b826c737333fab5b1f8e03fa7eb9a4799c4c1
|
||||
F src/table.c 0f141b58a16de7e2fbe81c308379e7279f4c6b50eb08efeec5892794a0ba30d1
|
||||
@@ -629,7 +629,7 @@ F src/vxworks.h d2988f4e5a61a4dfe82c6524dd3d6e4f2ce3cdb9
|
||||
F src/wal.c 69e770e96fd56cc21608992bf2c6f1f3dc5cf2572d0495c6a643b06c3a679f14
|
||||
F src/wal.h c3aa7825bfa2fe0d85bef2db94655f99870a285778baa36307c0a16da32b226a
|
||||
F src/walker.c d42d6c80ea363ef689a462e65eefcfe87deab924c50de5baa37ecb6af7d7ddaa
|
||||
F src/where.c 10d06b16670a1d2a992d52a9f08e49426d38a08fb0a7ae5f7f62fd023d560e1e
|
||||
F src/where.c 07d1232df6fc4705815b0ef5182fe3e56bdba6ac09ce52bd66ecb207626aac2b
|
||||
F src/whereInt.h 446e5e8018f83358ef917cf32d8e6a86dc8430113d0b17e720f1839d3faa44c4
|
||||
F src/wherecode.c c7354c9749f015f37bc32e15a4257a5155fa5d2b79f605f528bd09f3b9f1b4e6
|
||||
F src/whereexpr.c 53452fe2fb07be2f4cb17f55cc721416fae0092c00717f106faf289c990b6494
|
||||
@@ -845,7 +845,7 @@ F test/descidx3.test 953c831df7ea219c73826dfbf2f6ee02d95040725aa88ccb4fa43d1a199
|
||||
F test/diskfull.test 106391384780753ea6896b7b4f005d10e9866b6e
|
||||
F test/distinct.test e7d0cf371944dd0cbedff86420744e2f1ea2b528156451c97eb6ff41a99b9236
|
||||
F test/distinct2.test cd1d15a4a2abf579298f7161e821ed50c0119136fe0424db85c52cf0adc230d1
|
||||
F test/distinctagg.test 1a6ef9c87a58669438fc771450d7a72577417376
|
||||
F test/distinctagg.test fd74c3783700f1d99c67a5d906bba97fb6650f4559f3ea7b1873f793ffc601c9
|
||||
F test/e_blobbytes.test 439a945953b35cb6948a552edaec4dc31fd70a05
|
||||
F test/e_blobclose.test 4b3c8c60c2171164d472059c73e9f3c1844bb66d
|
||||
F test/e_blobopen.test e95e1d40f995056f6f322cd5e1a1b83a27e1a145
|
||||
@@ -1911,7 +1911,8 @@ F vsixtest/vsixtest.tcl 6a9a6ab600c25a91a7acc6293828957a386a8a93
|
||||
F vsixtest/vsixtest.vcxproj.data 2ed517e100c66dc455b492e1a33350c1b20fbcdc
|
||||
F vsixtest/vsixtest.vcxproj.filters 37e51ffedcdb064aad6ff33b6148725226cd608e
|
||||
F vsixtest/vsixtest_TemporaryKey.pfx e5b1b036facdb453873e7084e1cae9102ccc67a0
|
||||
P 4719fae6262aa3563f3df6aca0170c6d847bb18ab7b0e6e7609a0e7b6f0c6b1b
|
||||
R 093f7ddcde844a1b0a09d85353c82d32
|
||||
P 26b005a95e4f3e378e3bc40f57321ffbab72b6fc990d13b56b3121990d325f63 0817cf2ec08fdefd3c1d41790df7b5d6d490767757b44bb0229694023c8e40fc
|
||||
R 299a3406efa01e76d5f6f5a54ae9efc6
|
||||
T +closed 0817cf2ec08fdefd3c1d41790df7b5d6d490767757b44bb0229694023c8e40fc
|
||||
U drh
|
||||
Z ca39b787d3eb107a70be25725e1e0c65
|
||||
Z 8f54305fe91515917058141910a21763
|
||||
|
||||
@@ -1 +1 @@
|
||||
26b005a95e4f3e378e3bc40f57321ffbab72b6fc990d13b56b3121990d325f63
|
||||
ef4ac0ddd297bbd38351410c5a387e1628561b3f1bec9e4c2c9d76fbe29f955a
|
||||
269
src/select.c
269
src/select.c
@@ -741,31 +741,146 @@ static void codeOffset(
|
||||
}
|
||||
|
||||
/*
|
||||
** Add code that will check to make sure the N registers starting at iMem
|
||||
** form a distinct entry. iTab is a sorting index that holds previously
|
||||
** seen combinations of the N values. A new entry is made in iTab
|
||||
** if the current N values are new.
|
||||
** Add code that will check to make sure the array of registers starting at
|
||||
** iMem form a distinct entry. This is used by both "SELECT DISTINCT ..." and
|
||||
** distinct aggregates ("SELECT count(DISTINCT <expr>) ..."). Three strategies
|
||||
** are available. Which is used depends on the value of parameter eTnctType,
|
||||
** as follows:
|
||||
**
|
||||
** A jump to addrRepeat is made and the N+1 values are popped from the
|
||||
** stack if the top N elements are not distinct.
|
||||
** WHERE_DISTINCT_UNORDERED/WHERE_DISTINCT_NOOP:
|
||||
** Parameter iTab is the cursor number of an ephemeral table that must
|
||||
** be opened before the VM code generated by this routine is executed.
|
||||
** The ephemeral cursor table is queried for a record identical to the
|
||||
** record formed by the current array of registers. If one is found,
|
||||
** jump to VM address addrRepeat. Otherwise, insert a new record into
|
||||
** the ephemeral cursor and proceed.
|
||||
**
|
||||
** The returned value in this case is a copy of parameter iTab.
|
||||
**
|
||||
** WHERE_DISTINCT_ORDERED:
|
||||
** In this case rows are being delivered sorted order sorted. The ephermal
|
||||
** table is not required in this case. Instead, the current set of
|
||||
** registers are compared to previous row. If they match, the new row
|
||||
** is not distinct and control jumps to VM address addrRepeat. Otherwise,
|
||||
** the VM program proceeds with processing the new row.
|
||||
**
|
||||
** The returned value in this case is the register number of the first
|
||||
** in an array of registers used to store the previous result row so that
|
||||
** it can be compared to the next. The caller must ensure that this cell
|
||||
** is initialized to NULL and has the "clear" flag set.
|
||||
**
|
||||
** WHERE_DISTINCT_UNIQUE:
|
||||
** In this case it has already been determined that the rows are distinct.
|
||||
** No special action is required. The return value is always zero.
|
||||
**
|
||||
** Parameter pEList is the list of expressions used to generated the
|
||||
** contents of each row. It is used by this routine to determine (a)
|
||||
** how many elements there are in the array of registers and (b) the
|
||||
** collation sequences that should be used for the comparisons if
|
||||
** eTnctType is WHERE_DISTINCT_ORDERED.
|
||||
*/
|
||||
static void codeDistinct(
|
||||
static int codeDistinct(
|
||||
Parse *pParse, /* Parsing and code generating context */
|
||||
int eTnctType, /* WHERE_DISTINCT_* value */
|
||||
int iTab, /* A sorting index used to test for distinctness */
|
||||
int addrRepeat, /* Jump to here if not distinct */
|
||||
int N, /* Number of elements */
|
||||
int iMem /* First element */
|
||||
ExprList *pEList, /* Expression for each element */
|
||||
int regElem /* First element */
|
||||
){
|
||||
Vdbe *v;
|
||||
int r1;
|
||||
int iRet = 0;
|
||||
int nResultCol = pEList->nExpr;
|
||||
Vdbe *v = pParse->pVdbe;
|
||||
|
||||
v = pParse->pVdbe;
|
||||
r1 = sqlite3GetTempReg(pParse);
|
||||
sqlite3VdbeAddOp4Int(v, OP_Found, iTab, addrRepeat, iMem, N); VdbeCoverage(v);
|
||||
sqlite3VdbeAddOp3(v, OP_MakeRecord, iMem, N, r1);
|
||||
sqlite3VdbeAddOp4Int(v, OP_IdxInsert, iTab, r1, iMem, N);
|
||||
sqlite3VdbeChangeP5(v, OPFLAG_USESEEKRESULT);
|
||||
sqlite3ReleaseTempReg(pParse, r1);
|
||||
switch( eTnctType ){
|
||||
case WHERE_DISTINCT_ORDERED: {
|
||||
int i;
|
||||
int iJump; /* Jump destination */
|
||||
int regPrev; /* Previous row content */
|
||||
|
||||
/* Allocate space for the previous row */
|
||||
iRet = regPrev = pParse->nMem+1;
|
||||
pParse->nMem += nResultCol;
|
||||
|
||||
iJump = sqlite3VdbeCurrentAddr(v) + nResultCol;
|
||||
for(i=0; i<nResultCol; i++){
|
||||
CollSeq *pColl = sqlite3ExprCollSeq(pParse, pEList->a[i].pExpr);
|
||||
if( i<nResultCol-1 ){
|
||||
sqlite3VdbeAddOp3(v, OP_Ne, regElem+i, iJump, regPrev+i);
|
||||
VdbeCoverage(v);
|
||||
}else{
|
||||
sqlite3VdbeAddOp3(v, OP_Eq, regElem+i, addrRepeat, regPrev+i);
|
||||
VdbeCoverage(v);
|
||||
}
|
||||
sqlite3VdbeChangeP4(v, -1, (const char *)pColl, P4_COLLSEQ);
|
||||
sqlite3VdbeChangeP5(v, SQLITE_NULLEQ);
|
||||
}
|
||||
assert( sqlite3VdbeCurrentAddr(v)==iJump || pParse->db->mallocFailed );
|
||||
sqlite3VdbeAddOp3(v, OP_Copy, regElem, regPrev, nResultCol-1);
|
||||
break;
|
||||
}
|
||||
|
||||
case WHERE_DISTINCT_UNIQUE: {
|
||||
/* nothing to do */
|
||||
break;
|
||||
}
|
||||
|
||||
default: {
|
||||
int r1 = sqlite3GetTempReg(pParse);
|
||||
sqlite3VdbeAddOp4Int(v, OP_Found, iTab, addrRepeat, regElem, nResultCol);
|
||||
VdbeCoverage(v);
|
||||
sqlite3VdbeAddOp3(v, OP_MakeRecord, regElem, nResultCol, r1);
|
||||
sqlite3VdbeAddOp4Int(v, OP_IdxInsert, iTab, r1, regElem, nResultCol);
|
||||
sqlite3VdbeChangeP5(v, OPFLAG_USESEEKRESULT);
|
||||
sqlite3ReleaseTempReg(pParse, r1);
|
||||
iRet = iTab;
|
||||
break;
|
||||
}
|
||||
}
|
||||
|
||||
return iRet;
|
||||
}
|
||||
|
||||
/*
|
||||
** A call to this function must be made for each call to codeDistinct().
|
||||
** Parameter is passed the value returned by that call to codeDistinct(),
|
||||
** and iOpenEphAddr the address of the instruction used to open the
|
||||
** ephemeral table (that may be) used by codeDistinct().
|
||||
**
|
||||
** Argument eTnctType is passed the strategy to be used for any DISTINCT
|
||||
** operation, as returned by sqlite3WhereIsDistinct(). If the strategy
|
||||
** is WHERE_DISTINCT_NOOP or WHERE_DISTINCT_UNORDERED, this function is
|
||||
** a no-op. Otherwise:
|
||||
**
|
||||
** WHERE_DISTINCT_UNIQUE:
|
||||
** In this case the ephemeral table is not required. So instruction
|
||||
** iOpenEphAddr is replaced by an OP_Noop.
|
||||
**
|
||||
** WHERE_DISTINCT_ORDERED:
|
||||
** In this case the ephemeral table is not required. The instruction
|
||||
** iOpenEphAddr is replaced by an OP_Null instruction to set register
|
||||
** iVal to a NULL value with the "clear" flag set (see comments above
|
||||
** codeDistinct() for details).
|
||||
*/
|
||||
static void fixDistinctOpenEph(
|
||||
Parse *pParse, /* Parsing and code generating context */
|
||||
int eTnctType, /* WHERE_DISTINCT_* value */
|
||||
int iVal, /* Value returned by codeDistinct() */
|
||||
int iOpenEphAddr /* Address of OP_OpenEphemeral instruction for iTab */
|
||||
){
|
||||
if( eTnctType==WHERE_DISTINCT_UNIQUE || eTnctType==WHERE_DISTINCT_ORDERED ){
|
||||
Vdbe *v = pParse->pVdbe;
|
||||
sqlite3VdbeChangeToNoop(v, iOpenEphAddr);
|
||||
if( eTnctType==WHERE_DISTINCT_ORDERED ){
|
||||
/* Change the OP_OpenEphemeral to an OP_Null that sets the MEM_Cleared
|
||||
** bit on the first register of the previous value. This will cause the
|
||||
** OP_Ne added in codeDistinct() to always fail on the first iteration of
|
||||
** the loop even if the first row is all NULLs. */
|
||||
VdbeOp *pOp = sqlite3VdbeGetOp(v, iOpenEphAddr);
|
||||
pOp->opcode = OP_Null;
|
||||
pOp->p1 = 1;
|
||||
pOp->p2 = iVal;
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
#ifdef SQLITE_ENABLE_SORTER_REFERENCES
|
||||
@@ -1013,59 +1128,11 @@ static void selectInnerLoop(
|
||||
** part of the result.
|
||||
*/
|
||||
if( hasDistinct ){
|
||||
switch( pDistinct->eTnctType ){
|
||||
case WHERE_DISTINCT_ORDERED: {
|
||||
VdbeOp *pOp; /* No longer required OpenEphemeral instr. */
|
||||
int iJump; /* Jump destination */
|
||||
int regPrev; /* Previous row content */
|
||||
|
||||
/* Allocate space for the previous row */
|
||||
regPrev = pParse->nMem+1;
|
||||
pParse->nMem += nResultCol;
|
||||
|
||||
/* Change the OP_OpenEphemeral coded earlier to an OP_Null
|
||||
** sets the MEM_Cleared bit on the first register of the
|
||||
** previous value. This will cause the OP_Ne below to always
|
||||
** fail on the first iteration of the loop even if the first
|
||||
** row is all NULLs.
|
||||
*/
|
||||
sqlite3VdbeChangeToNoop(v, pDistinct->addrTnct);
|
||||
pOp = sqlite3VdbeGetOp(v, pDistinct->addrTnct);
|
||||
pOp->opcode = OP_Null;
|
||||
pOp->p1 = 1;
|
||||
pOp->p2 = regPrev;
|
||||
pOp = 0; /* Ensure pOp is not used after sqlite3VdbeAddOp() */
|
||||
|
||||
iJump = sqlite3VdbeCurrentAddr(v) + nResultCol;
|
||||
for(i=0; i<nResultCol; i++){
|
||||
CollSeq *pColl = sqlite3ExprCollSeq(pParse, p->pEList->a[i].pExpr);
|
||||
if( i<nResultCol-1 ){
|
||||
sqlite3VdbeAddOp3(v, OP_Ne, regResult+i, iJump, regPrev+i);
|
||||
VdbeCoverage(v);
|
||||
}else{
|
||||
sqlite3VdbeAddOp3(v, OP_Eq, regResult+i, iContinue, regPrev+i);
|
||||
VdbeCoverage(v);
|
||||
}
|
||||
sqlite3VdbeChangeP4(v, -1, (const char *)pColl, P4_COLLSEQ);
|
||||
sqlite3VdbeChangeP5(v, SQLITE_NULLEQ);
|
||||
}
|
||||
assert( sqlite3VdbeCurrentAddr(v)==iJump || pParse->db->mallocFailed );
|
||||
sqlite3VdbeAddOp3(v, OP_Copy, regResult, regPrev, nResultCol-1);
|
||||
break;
|
||||
}
|
||||
|
||||
case WHERE_DISTINCT_UNIQUE: {
|
||||
sqlite3VdbeChangeToNoop(v, pDistinct->addrTnct);
|
||||
break;
|
||||
}
|
||||
|
||||
default: {
|
||||
assert( pDistinct->eTnctType==WHERE_DISTINCT_UNORDERED );
|
||||
codeDistinct(pParse, pDistinct->tabTnct, iContinue, nResultCol,
|
||||
regResult);
|
||||
break;
|
||||
}
|
||||
}
|
||||
int eType = pDistinct->eTnctType;
|
||||
int iTab = pDistinct->tabTnct;
|
||||
assert( nResultCol==p->pEList->nExpr );
|
||||
iTab = codeDistinct(pParse, eType, iTab, iContinue, p->pEList, regResult);
|
||||
fixDistinctOpenEph(pParse, eType, iTab, pDistinct->addrTnct);
|
||||
if( pSort==0 ){
|
||||
codeOffset(v, p->iOffset, iContinue);
|
||||
}
|
||||
@@ -5645,8 +5712,8 @@ static void resetAccumulator(Parse *pParse, AggInfo *pAggInfo){
|
||||
pFunc->iDistinct = -1;
|
||||
}else{
|
||||
KeyInfo *pKeyInfo = sqlite3KeyInfoFromExprList(pParse, pE->x.pList,0,0);
|
||||
sqlite3VdbeAddOp4(v, OP_OpenEphemeral, pFunc->iDistinct, 0, 0,
|
||||
(char*)pKeyInfo, P4_KEYINFO);
|
||||
pFunc->iDistAddr = sqlite3VdbeAddOp4(v, OP_OpenEphemeral,
|
||||
pFunc->iDistinct, 0, 0, (char*)pKeyInfo, P4_KEYINFO);
|
||||
}
|
||||
}
|
||||
}
|
||||
@@ -5678,7 +5745,12 @@ static void finalizeAggFunctions(Parse *pParse, AggInfo *pAggInfo){
|
||||
** registers if register regAcc contains 0. The caller will take care
|
||||
** of setting and clearing regAcc.
|
||||
*/
|
||||
static void updateAccumulator(Parse *pParse, int regAcc, AggInfo *pAggInfo){
|
||||
static void updateAccumulator(
|
||||
Parse *pParse,
|
||||
int regAcc,
|
||||
AggInfo *pAggInfo,
|
||||
int eDistinctType
|
||||
){
|
||||
Vdbe *v = pParse->pVdbe;
|
||||
int i;
|
||||
int regHit = 0;
|
||||
@@ -5724,13 +5796,14 @@ static void updateAccumulator(Parse *pParse, int regAcc, AggInfo *pAggInfo){
|
||||
nArg = 0;
|
||||
regAgg = 0;
|
||||
}
|
||||
if( pF->iDistinct>=0 ){
|
||||
if( pF->iDistinct>=0 && pList ){
|
||||
if( addrNext==0 ){
|
||||
addrNext = sqlite3VdbeMakeLabel(pParse);
|
||||
}
|
||||
testcase( nArg==0 ); /* Error condition */
|
||||
testcase( nArg>1 ); /* Also an error */
|
||||
codeDistinct(pParse, pF->iDistinct, addrNext, 1, regAgg);
|
||||
pF->iDistinct = codeDistinct(pParse, eDistinctType,
|
||||
pF->iDistinct, addrNext, pList, regAgg);
|
||||
}
|
||||
if( pF->pFunc->funcFlags & SQLITE_FUNC_NEEDCOLL ){
|
||||
CollSeq *pColl = 0;
|
||||
@@ -6762,6 +6835,20 @@ int sqlite3Select(
|
||||
int addrSortingIdx; /* The OP_OpenEphemeral for the sorting index */
|
||||
int addrReset; /* Subroutine for resetting the accumulator */
|
||||
int regReset; /* Return address register for reset subroutine */
|
||||
ExprList *pDistinct = 0;
|
||||
u16 distFlag = 0;
|
||||
int eDist = WHERE_DISTINCT_NOOP;
|
||||
|
||||
if( pAggInfo->nFunc==1
|
||||
&& pAggInfo->aFunc[0].iDistinct>=0
|
||||
&& pAggInfo->aFunc[0].pFExpr->x.pList
|
||||
){
|
||||
Expr *pExpr = pAggInfo->aFunc[0].pFExpr->x.pList->a[0].pExpr;
|
||||
pExpr = sqlite3ExprDup(db, pExpr, 0);
|
||||
pDistinct = sqlite3ExprListDup(db, pGroupBy, 0);
|
||||
pDistinct = sqlite3ExprListAppend(pParse, pDistinct, pExpr);
|
||||
distFlag = pDistinct ? WHERE_WANT_DISTINCT : 0;
|
||||
}
|
||||
|
||||
/* If there is a GROUP BY clause we might need a sorting index to
|
||||
** implement it. Allocate that sorting index now. If it turns out
|
||||
@@ -6798,10 +6885,12 @@ int sqlite3Select(
|
||||
*/
|
||||
sqlite3VdbeAddOp2(v, OP_Gosub, regReset, addrReset);
|
||||
SELECTTRACE(1,pParse,p,("WhereBegin\n"));
|
||||
pWInfo = sqlite3WhereBegin(pParse, pTabList, pWhere, pGroupBy, 0,
|
||||
WHERE_GROUPBY | (orderByGrp ? WHERE_SORTBYGROUP : 0), 0
|
||||
pWInfo = sqlite3WhereBegin(pParse, pTabList, pWhere, pGroupBy, pDistinct,
|
||||
WHERE_GROUPBY | (orderByGrp ? WHERE_SORTBYGROUP : 0) | distFlag, 0
|
||||
);
|
||||
sqlite3ExprListDelete(db, pDistinct);
|
||||
if( pWInfo==0 ) goto select_end;
|
||||
eDist = sqlite3WhereIsDistinct(pWInfo);
|
||||
SELECTTRACE(1,pParse,p,("WhereBegin returns\n"));
|
||||
if( sqlite3WhereIsOrdered(pWInfo)==pGroupBy->nExpr ){
|
||||
/* The optimizer is able to deliver rows in group by order so
|
||||
@@ -6919,7 +7008,7 @@ int sqlite3Select(
|
||||
** the current row
|
||||
*/
|
||||
sqlite3VdbeJumpHere(v, addr1);
|
||||
updateAccumulator(pParse, iUseFlag, pAggInfo);
|
||||
updateAccumulator(pParse, iUseFlag, pAggInfo, eDist);
|
||||
sqlite3VdbeAddOp2(v, OP_Integer, 1, iUseFlag);
|
||||
VdbeComment((v, "indicate data in accumulator"));
|
||||
|
||||
@@ -6975,7 +7064,11 @@ int sqlite3Select(
|
||||
sqlite3VdbeAddOp2(v, OP_Integer, 0, iUseFlag);
|
||||
VdbeComment((v, "indicate accumulator empty"));
|
||||
sqlite3VdbeAddOp1(v, OP_Return, regReset);
|
||||
|
||||
|
||||
if( eDist!=WHERE_DISTINCT_NOOP ){
|
||||
struct AggInfo_func *pF = &pAggInfo->aFunc[0];
|
||||
fixDistinctOpenEph(pParse, eDist, pF->iDistinct, pF->iDistAddr);
|
||||
}
|
||||
} /* endif pGroupBy. Begin aggregate queries without GROUP BY: */
|
||||
else {
|
||||
Table *pTab;
|
||||
@@ -7039,6 +7132,9 @@ int sqlite3Select(
|
||||
explainSimpleCount(pParse, pTab, pBest);
|
||||
}else{
|
||||
int regAcc = 0; /* "populate accumulators" flag */
|
||||
ExprList *pDistinct = 0;
|
||||
u16 distFlag = 0;
|
||||
int eDist;
|
||||
|
||||
/* If there are accumulator registers but no min() or max() functions
|
||||
** without FILTER clauses, allocate register regAcc. Register regAcc
|
||||
@@ -7062,6 +7158,9 @@ int sqlite3Select(
|
||||
regAcc = ++pParse->nMem;
|
||||
sqlite3VdbeAddOp2(v, OP_Integer, 0, regAcc);
|
||||
}
|
||||
}else if( pAggInfo->nFunc==1 && pAggInfo->aFunc[0].iDistinct>=0 ){
|
||||
pDistinct = pAggInfo->aFunc[0].pFExpr->x.pList;
|
||||
distFlag = pDistinct ? WHERE_WANT_DISTINCT : 0;
|
||||
}
|
||||
|
||||
/* This case runs if the aggregate has no GROUP BY clause. The
|
||||
@@ -7081,12 +7180,18 @@ int sqlite3Select(
|
||||
|
||||
SELECTTRACE(1,pParse,p,("WhereBegin\n"));
|
||||
pWInfo = sqlite3WhereBegin(pParse, pTabList, pWhere, pMinMaxOrderBy,
|
||||
0, minMaxFlag, 0);
|
||||
pDistinct, minMaxFlag|distFlag, 0);
|
||||
if( pWInfo==0 ){
|
||||
goto select_end;
|
||||
}
|
||||
SELECTTRACE(1,pParse,p,("WhereBegin returns\n"));
|
||||
updateAccumulator(pParse, regAcc, pAggInfo);
|
||||
eDist = sqlite3WhereIsDistinct(pWInfo);
|
||||
updateAccumulator(pParse, regAcc, pAggInfo, eDist);
|
||||
if( eDist!=WHERE_DISTINCT_NOOP ){
|
||||
struct AggInfo_func *pF = &pAggInfo->aFunc[0];
|
||||
fixDistinctOpenEph(pParse, eDist, pF->iDistinct, pF->iDistAddr);
|
||||
}
|
||||
|
||||
if( regAcc ) sqlite3VdbeAddOp2(v, OP_Integer, 1, regAcc);
|
||||
if( minMaxFlag ){
|
||||
sqlite3WhereMinMaxOptEarlyOut(v, pWInfo);
|
||||
|
||||
@@ -2603,6 +2603,7 @@ struct AggInfo {
|
||||
FuncDef *pFunc; /* The aggregate function implementation */
|
||||
int iMem; /* Memory location that acts as accumulator */
|
||||
int iDistinct; /* Ephemeral table used to enforce DISTINCT */
|
||||
int iDistAddr; /* Address of OP_OpenEphemeral */
|
||||
} *aFunc;
|
||||
int nFunc; /* Number of entries in aFunc[] */
|
||||
u32 selId; /* Select to which this AggInfo belongs */
|
||||
|
||||
13
src/where.c
13
src/where.c
@@ -492,7 +492,7 @@ static int findIndexCol(
|
||||
for(i=0; i<pList->nExpr; i++){
|
||||
Expr *p = sqlite3ExprSkipCollateAndLikely(pList->a[i].pExpr);
|
||||
if( ALWAYS(p!=0)
|
||||
&& p->op==TK_COLUMN
|
||||
&& (p->op==TK_COLUMN || p->op==TK_AGG_COLUMN)
|
||||
&& p->iColumn==pIdx->aiColumn[iCol]
|
||||
&& p->iTable==iBase
|
||||
){
|
||||
@@ -557,7 +557,8 @@ static int isDistinctRedundant(
|
||||
for(i=0; i<pDistinct->nExpr; i++){
|
||||
Expr *p = sqlite3ExprSkipCollateAndLikely(pDistinct->a[i].pExpr);
|
||||
if( NEVER(p==0) ) continue;
|
||||
if( p->op==TK_COLUMN && p->iTable==iBase && p->iColumn<0 ) return 1;
|
||||
if( p->op!=TK_COLUMN && p->op!=TK_AGG_COLUMN ) continue;
|
||||
if( p->iTable==iBase && p->iColumn<0 ) return 1;
|
||||
}
|
||||
|
||||
/* Loop through all indices on the table, checking each to see if it makes
|
||||
@@ -3822,7 +3823,7 @@ static i8 wherePathSatisfiesOrderBy(
|
||||
if( MASKBIT(i) & obSat ) continue;
|
||||
pOBExpr = sqlite3ExprSkipCollateAndLikely(pOrderBy->a[i].pExpr);
|
||||
if( NEVER(pOBExpr==0) ) continue;
|
||||
if( pOBExpr->op!=TK_COLUMN ) continue;
|
||||
if( pOBExpr->op!=TK_COLUMN && pOBExpr->op!=TK_AGG_COLUMN ) continue;
|
||||
if( pOBExpr->iTable!=iCur ) continue;
|
||||
pTerm = sqlite3WhereFindTerm(&pWInfo->sWC, iCur, pOBExpr->iColumn,
|
||||
~ready, eqOpMask, 0);
|
||||
@@ -3951,7 +3952,7 @@ static i8 wherePathSatisfiesOrderBy(
|
||||
if( NEVER(pOBExpr==0) ) continue;
|
||||
if( (wctrlFlags & (WHERE_GROUPBY|WHERE_DISTINCTBY))==0 ) bOnce = 0;
|
||||
if( iColumn>=XN_ROWID ){
|
||||
if( pOBExpr->op!=TK_COLUMN ) continue;
|
||||
if( pOBExpr->op!=TK_COLUMN && pOBExpr->op!=TK_AGG_COLUMN ) continue;
|
||||
if( pOBExpr->iTable!=iCur ) continue;
|
||||
if( pOBExpr->iColumn!=iColumn ) continue;
|
||||
}else{
|
||||
@@ -5024,7 +5025,9 @@ WhereInfo *sqlite3WhereBegin(
|
||||
/* Attempt to omit tables from the join that do not affect the result.
|
||||
** For a table to not affect the result, the following must be true:
|
||||
**
|
||||
** 1) The query must not be an aggregate.
|
||||
** 1) The query must not be an aggregate. Or it must be an aggregate
|
||||
** that contains only one aggregate function with the DISTINCT
|
||||
** qualifier. e.g. "SELECT count(DISTINCT ...) FROM".
|
||||
** 2) The table must be the RHS of a LEFT JOIN.
|
||||
** 3) Either the query must be DISTINCT, or else the ON or USING clause
|
||||
** must contain a constraint that limits the scan of the table to
|
||||
|
||||
@@ -16,6 +16,7 @@
|
||||
|
||||
set testdir [file dirname $argv0]
|
||||
source $testdir/tester.tcl
|
||||
set testprefix distinctagg
|
||||
|
||||
do_test distinctagg-1.1 {
|
||||
execsql {
|
||||
@@ -31,7 +32,7 @@ do_test distinctagg-1.1 {
|
||||
} {1 2 3 3}
|
||||
do_test distinctagg-1.2 {
|
||||
execsql {
|
||||
SELECT b, count(distinct c) FROM t1 GROUP BY b ORDER BY b
|
||||
SELECT b, count(distinct c) FROM t1 GROUP BY b
|
||||
}
|
||||
} {2 1 3 2}
|
||||
do_test distinctagg-1.3 {
|
||||
@@ -59,4 +60,135 @@ do_test distinctagg-2.2 {
|
||||
}
|
||||
} {1 {DISTINCT aggregates must have exactly one argument}}
|
||||
|
||||
#--------------------------------------------------------------------------
|
||||
reset_db
|
||||
do_execsql_test 3.0 {
|
||||
CREATE TABLE t1(a, b, c);
|
||||
CREATE TABLE t2(d, e, f);
|
||||
|
||||
INSERT INTO t1 VALUES (1, 1, 1);
|
||||
INSERT INTO t1 VALUES (2, 2, 2);
|
||||
INSERT INTO t1 VALUES (3, 3, 3);
|
||||
INSERT INTO t1 VALUES (4, 1, 4);
|
||||
INSERT INTO t1 VALUES (5, 2, 1);
|
||||
INSERT INTO t1 VALUES (5, 3, 2);
|
||||
INSERT INTO t1 VALUES (4, 1, 3);
|
||||
INSERT INTO t1 VALUES (3, 2, 4);
|
||||
INSERT INTO t1 VALUES (2, 3, 1);
|
||||
INSERT INTO t1 VALUES (1, 1, 2);
|
||||
|
||||
INSERT INTO t2 VALUES('a', 'a', 'a');
|
||||
INSERT INTO t2 VALUES('b', 'b', 'b');
|
||||
INSERT INTO t2 VALUES('c', 'c', 'c');
|
||||
|
||||
CREATE INDEX t1a ON t1(a);
|
||||
CREATE INDEX t1bc ON t1(b, c);
|
||||
}
|
||||
|
||||
foreach {tn use_eph sql res} {
|
||||
1 0 "SELECT count(DISTINCT a) FROM t1" 5
|
||||
2 0 "SELECT count(DISTINCT b) FROM t1" 3
|
||||
3 1 "SELECT count(DISTINCT c) FROM t1" 4
|
||||
4 0 "SELECT count(DISTINCT c) FROM t1 WHERE b=3" 3
|
||||
5 0 "SELECT count(DISTINCT rowid) FROM t1" 10
|
||||
6 0 "SELECT count(DISTINCT a) FROM t1, t2" 5
|
||||
7 0 "SELECT count(DISTINCT a) FROM t2, t1" 5
|
||||
8 1 "SELECT count(DISTINCT a+b) FROM t1, t2, t2, t2" 6
|
||||
9 0 "SELECT count(DISTINCT c) FROM t1 WHERE c=2" 1
|
||||
10 1 "SELECT count(DISTINCT t1.rowid) FROM t1, t2" 10
|
||||
} {
|
||||
do_test 3.$tn.1 {
|
||||
set prg [db eval "EXPLAIN $sql"]
|
||||
set idx [lsearch $prg OpenEphemeral]
|
||||
expr {$idx>=0}
|
||||
} $use_eph
|
||||
|
||||
do_execsql_test 3.$tn.2 $sql $res
|
||||
}
|
||||
|
||||
do_execsql_test 3.10 {
|
||||
SELECT a, count(DISTINCT b) FROM t1 GROUP BY a;
|
||||
} {
|
||||
1 1 2 2 3 2 4 1 5 2
|
||||
}
|
||||
|
||||
#--------------------------------------------------------------------------
|
||||
reset_db
|
||||
do_execsql_test 3.0 {
|
||||
CREATE TABLE t1(a, b, c);
|
||||
CREATE INDEX t1a ON t1(a);
|
||||
CREATE INDEX t1bc ON t1(b, c);
|
||||
|
||||
INSERT INTO t1 VALUES(1, 'A', 1);
|
||||
INSERT INTO t1 VALUES(1, 'A', 1);
|
||||
INSERT INTO t1 VALUES(2, 'A', 2);
|
||||
INSERT INTO t1 VALUES(2, 'A', 2);
|
||||
INSERT INTO t1 VALUES(1, 'B', 1);
|
||||
INSERT INTO t1 VALUES(2, 'B', 2);
|
||||
INSERT INTO t1 VALUES(3, 'B', 3);
|
||||
INSERT INTO t1 VALUES(NULL, 'B', NULL);
|
||||
INSERT INTO t1 VALUES(NULL, 'C', NULL);
|
||||
INSERT INTO t1 VALUES('d', 'D', 'd');
|
||||
|
||||
CREATE TABLE t2(d, e, f);
|
||||
CREATE INDEX t2def ON t2(d, e, f);
|
||||
|
||||
INSERT INTO t2 VALUES(1, 1, 'a');
|
||||
INSERT INTO t2 VALUES(1, 1, 'a');
|
||||
INSERT INTO t2 VALUES(1, 2, 'a');
|
||||
INSERT INTO t2 VALUES(1, 2, 'a');
|
||||
INSERT INTO t2 VALUES(1, 2, 'b');
|
||||
INSERT INTO t2 VALUES(1, 3, 'b');
|
||||
INSERT INTO t2 VALUES(1, 3, 'a');
|
||||
INSERT INTO t2 VALUES(1, 3, 'b');
|
||||
INSERT INTO t2 VALUES(2, 3, 'x');
|
||||
INSERT INTO t2 VALUES(2, 3, 'y');
|
||||
INSERT INTO t2 VALUES(2, 3, 'z');
|
||||
|
||||
CREATE TABLE t3(x, y, z);
|
||||
INSERT INTO t3 VALUES(1,1,1);
|
||||
INSERT INTO t3 VALUES(2,2,2);
|
||||
}
|
||||
|
||||
foreach {tn use_eph sql res} {
|
||||
1 0 "SELECT count(DISTINCT c) FROM t1 GROUP BY b" {2 3 0 1}
|
||||
2 1 "SELECT count(DISTINCT a) FROM t1 GROUP BY b" {2 3 0 1}
|
||||
3 1 "SELECT count(DISTINCT a) FROM t1 GROUP BY b+c" {0 1 1 1 1}
|
||||
|
||||
4 0 "SELECT count(DISTINCT f) FROM t2 GROUP BY d, e" {1 2 2 3}
|
||||
5 1 "SELECT count(DISTINCT f) FROM t2 GROUP BY d" {2 3}
|
||||
6 0 "SELECT count(DISTINCT f) FROM t2 WHERE d IS 1 GROUP BY e" {1 2 2}
|
||||
} {
|
||||
do_test 4.$tn.1 {
|
||||
set prg [db eval "EXPLAIN $sql"]
|
||||
set idx [lsearch $prg OpenEphemeral]
|
||||
expr {$idx>=0}
|
||||
} $use_eph
|
||||
|
||||
do_execsql_test 4.$tn.2 $sql $res
|
||||
}
|
||||
|
||||
|
||||
set t3root [db one {SELECT rootpage FROM sqlite_schema WHERE name='t3'}]
|
||||
foreach {tn use_t3 sql res} {
|
||||
1 1 "SELECT count(*) FROM t3" 2
|
||||
2 0 "SELECT count(*) FROM t1" 10
|
||||
2 1 "SELECT count(DISTINCT a) FROM t1, t3" 4
|
||||
3 0 "SELECT count(DISTINCT a) FROM t1 LEFT JOIN t3" 4
|
||||
4 1 "SELECT count(DISTINCT a) FROM t1 LEFT JOIN t3 WHERE t3.x=1" 4
|
||||
5 1 "SELECT count(DISTINCT a) FROM t1 LEFT JOIN t3 WHERE t3.x=0" 0
|
||||
6 0 "SELECT count(DISTINCT a) FROM t1 LEFT JOIN t3 ON (t3.x=0)" 4
|
||||
} {
|
||||
do_test 5.$tn.1 {
|
||||
set bUse 0
|
||||
db eval "EXPLAIN $sql" a {
|
||||
if {$a(opcode)=="OpenRead" && $a(p2)==$t3root} {set bUse 1}
|
||||
}
|
||||
set bUse
|
||||
} $use_t3
|
||||
|
||||
do_execsql_test 5.$tn.2 $sql $res
|
||||
}
|
||||
|
||||
finish_test
|
||||
|
||||
|
||||
Reference in New Issue
Block a user