SQLite

Check-in [da3fba18]
Login

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

Overview
Comment:New restriction on the push-down optimization to prevent an ON or USING clause on the left side of a RIGHT JOIN from being pushed down into a subquery that is on the right side of that RIGHT JOIN. Forum post a7d4be7fb6. This is similar to an earlier problem fixed at [1783655ea422185e]. Also add comments to describe previously undocumented push-down optimization restrictions.
Downloads: Tarball | ZIP archive | SQL archive
Timelines: family | ancestors | descendants | both | trunk
Files: files | file ages | folders
SHA3-256: da3fba18742b6e0bd5290bee9d86a2d5cb1ff2de25d737ef93060d7c1143273f
User & Date: drh 2023-05-10 00:33:21
Original Comment: New restriction on the push-down optimization to prevent an ON or USING clause on the left side of a RIGHT JOIN from being pushed down into a subquery that is on the right side of that RIGHT JOIN. Forum post a7d4be7fb6. Also add comments to describe previously undocumented push-down optimization restrictions.
References
2023-05-15
02:06
As evidenced by forum post f3f546025a, the new RIGHT JOIN related restriction on the push-down optimization implemented by [da3fba18742b6e0b] also needs to apply to the automatic index (a.k.a. hash-join) optimization and to the Bloom filter optimization. Computation of the restriction is now moved into the sqlite3ExprIsSingleTableConstraint() routine. (check-in: 4902015d user: drh tags: trunk)
Context
2023-05-10
10:03
Add a missing comma to the documentation for the OP_Jump opcode. No changes to code. (check-in: 7e2c2b1c user: drh tags: trunk)
00:33
New restriction on the push-down optimization to prevent an ON or USING clause on the left side of a RIGHT JOIN from being pushed down into a subquery that is on the right side of that RIGHT JOIN. Forum post a7d4be7fb6. This is similar to an earlier problem fixed at [1783655ea422185e]. Also add comments to describe previously undocumented push-down optimization restrictions. (check-in: da3fba18 user: drh tags: trunk)
00:20
Fix bug in fall-back logic of CLI .clone (check-in: 0dcd9785 user: larrybr tags: trunk)
Changes
Unified Diff Ignore Whitespace Patch
Changes to src/select.c.
5103
5104
5105
5106
5107
5108
5109

















5110
5111
5112
5113
5114
5115
5116
5117

5118
5119
5120

5121

5122
5123


5124


5125
5126
5127
5128
5129
5130
5131
**       be materialized.  (This restriction is implemented in the calling
**       routine.)
**
**   (8) If the subquery is a compound that uses UNION, INTERSECT,
**       or EXCEPT, then all of the result set columns for all arms of
**       the compound must use the BINARY collating sequence.
**

















**
** Return 0 if no changes are made and non-zero if one or more WHERE clause
** terms are duplicated into the subquery.
*/
static int pushDownWhereTerms(
  Parse *pParse,        /* Parse context (for malloc() and error reporting) */
  Select *pSubq,        /* The subquery whose WHERE clause is to be augmented */
  Expr *pWhere,         /* The WHERE clause of the outer query */

  SrcItem *pSrc         /* The subquery term of the outer FROM clause */
){
  Expr *pNew;

  int nChng = 0;

  if( pWhere==0 ) return 0;
  if( pSubq->selFlags & (SF_Recursive|SF_MultiPart) ) return 0;


  if( pSrc->fg.jointype & (JT_LTORJ|JT_RIGHT) ) return 0;



  if( pSubq->pPrior ){
    Select *pSel;
    int notUnionAll = 0;
    for(pSel=pSubq; pSel; pSel=pSel->pPrior){
      u8 op = pSel->op;
      assert( op==TK_ALL || op==TK_SELECT 







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








>
|


>

>

|
>
>
|
>
>







5103
5104
5105
5106
5107
5108
5109
5110
5111
5112
5113
5114
5115
5116
5117
5118
5119
5120
5121
5122
5123
5124
5125
5126
5127
5128
5129
5130
5131
5132
5133
5134
5135
5136
5137
5138
5139
5140
5141
5142
5143
5144
5145
5146
5147
5148
5149
5150
5151
5152
5153
5154
5155
**       be materialized.  (This restriction is implemented in the calling
**       routine.)
**
**   (8) If the subquery is a compound that uses UNION, INTERSECT,
**       or EXCEPT, then all of the result set columns for all arms of
**       the compound must use the BINARY collating sequence.
**
**   (9) All three of the following are true:
**
**       (9a) The WHERE clause expression originates in the ON or USING clause
**            of a join (either an INNER or an OUTER join), and
**
**       (9b) The subquery is to the right of the ON/USING clause
**
**       (9c) There is a RIGHT JOIN (or FULL JOIN) in between the ON/USING
**            clause and the subquery.
**
**       Without this restriction, the push-down optimization might move
**       the ON/USING filter expression from the left side of a RIGHT JOIN
**       over to the right side, which leads to incorrect answers.
**
**  (10) The inner query is not the right-hand table of a RIGHT JOIN.
**
**  (11) The subquery is not a VALUES clause
**
** Return 0 if no changes are made and non-zero if one or more WHERE clause
** terms are duplicated into the subquery.
*/
static int pushDownWhereTerms(
  Parse *pParse,        /* Parse context (for malloc() and error reporting) */
  Select *pSubq,        /* The subquery whose WHERE clause is to be augmented */
  Expr *pWhere,         /* The WHERE clause of the outer query */
  SrcList *pSrcList,    /* The complete from clause of the outer query */
  int iSrc              /* Which FROM clause term to try to push into  */
){
  Expr *pNew;
  SrcItem *pSrc;        /* The subquery FROM term into which WHERE is pushed */
  int nChng = 0;
  pSrc = &pSrcList->a[iSrc];
  if( pWhere==0 ) return 0;
  if( pSubq->selFlags & (SF_Recursive|SF_MultiPart) ){
    return 0;           /* restrictions (2) and (11) */
  }
  if( pSrc->fg.jointype & (JT_LTORJ|JT_RIGHT) ){
    return 0;           /* restrictions (10) */
  }

  if( pSubq->pPrior ){
    Select *pSel;
    int notUnionAll = 0;
    for(pSel=pSubq; pSel; pSel=pSel->pPrior){
      u8 op = pSel->op;
      assert( op==TK_ALL || op==TK_SELECT 
5172
5173
5174
5175
5176
5177
5178
5179
5180
5181


















5182
5183
5184
5185
5186
5187
5188
  }
#endif

  if( pSubq->pLimit!=0 ){
    return 0; /* restriction (3) */
  }
  while( pWhere->op==TK_AND ){
    nChng += pushDownWhereTerms(pParse, pSubq, pWhere->pRight, pSrc);
    pWhere = pWhere->pLeft;
  }



















#if 0  /* Legacy code. Checks now done by sqlite3ExprIsTableConstraint() */
  if( isLeftJoin
   && (ExprHasProperty(pWhere,EP_OuterON)==0
         || pWhere->w.iJoin!=iCursor)
  ){
    return 0; /* restriction (4) */







|


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







5196
5197
5198
5199
5200
5201
5202
5203
5204
5205
5206
5207
5208
5209
5210
5211
5212
5213
5214
5215
5216
5217
5218
5219
5220
5221
5222
5223
5224
5225
5226
5227
5228
5229
5230
  }
#endif

  if( pSubq->pLimit!=0 ){
    return 0; /* restriction (3) */
  }
  while( pWhere->op==TK_AND ){
    nChng += pushDownWhereTerms(pParse, pSubq, pWhere->pRight, pSrcList, iSrc);
    pWhere = pWhere->pLeft;
  }

  if( ExprHasProperty(pWhere, EP_OuterON|EP_InnerON) /* (9a) */
   && (pSrcList->a[0].fg.jointype & JT_LTORJ)!=0     /* Fast pre-test of (9c) */
  ){
    int jj;
    for(jj=0; jj<iSrc; jj++){
      if( pWhere->w.iJoin==pSrcList->a[jj].iCursor ){
        /* If we reach this point, both (9a) and (9b) are satisfied.
        ** The following loop checks (9c):
        */
        for(jj++; jj<iSrc; jj++){
          if( (pSrcList->a[jj].fg.jointype & JT_RIGHT)!=0 ){
            return 0;  /* restriction (9) */
          }
        }
      }
    }
  }

#if 0  /* Legacy code. Checks now done by sqlite3ExprIsTableConstraint() */
  if( isLeftJoin
   && (ExprHasProperty(pWhere,EP_OuterON)==0
         || pWhere->w.iJoin!=iCursor)
  ){
    return 0; /* restriction (4) */
7385
7386
7387
7388
7389
7390
7391
7392
7393
7394
7395
7396
7397
7398
7399

    /* Make copies of constant WHERE-clause terms in the outer query down
    ** inside the subquery.  This can help the subquery to run more efficiently.
    */
    if( OptimizationEnabled(db, SQLITE_PushDown)
     && (pItem->fg.isCte==0 
         || (pItem->u2.pCteUse->eM10d!=M10d_Yes && pItem->u2.pCteUse->nUse<2))
     && pushDownWhereTerms(pParse, pSub, p->pWhere, pItem)
    ){
#if TREETRACE_ENABLED
      if( sqlite3TreeTrace & 0x4000 ){
        TREETRACE(0x4000,pParse,p,
            ("After WHERE-clause push-down into subquery %d:\n", pSub->selId));
        sqlite3TreeViewSelect(0, p, 0);
      }







|







7427
7428
7429
7430
7431
7432
7433
7434
7435
7436
7437
7438
7439
7440
7441

    /* Make copies of constant WHERE-clause terms in the outer query down
    ** inside the subquery.  This can help the subquery to run more efficiently.
    */
    if( OptimizationEnabled(db, SQLITE_PushDown)
     && (pItem->fg.isCte==0 
         || (pItem->u2.pCteUse->eM10d!=M10d_Yes && pItem->u2.pCteUse->nUse<2))
     && pushDownWhereTerms(pParse, pSub, p->pWhere, pTabList, i)
    ){
#if TREETRACE_ENABLED
      if( sqlite3TreeTrace & 0x4000 ){
        TREETRACE(0x4000,pParse,p,
            ("After WHERE-clause push-down into subquery %d:\n", pSub->selId));
        sqlite3TreeViewSelect(0, p, 0);
      }
Changes to test/pushdown.test.
179
180
181
182
183
184
185























186
187
  |  `--SCAN t1
  `--SCALAR SUBQUERY xxxxxx
     `--SCAN t2
}
# ^^^^^^^^^^^^^^^^^^^^
# The query should be converted into:
#   SELECT (SELECT count(*) FROM t1)+(SELECT count(*) FROM t2)
























finish_test







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


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
  |  `--SCAN t1
  `--SCALAR SUBQUERY xxxxxx
     `--SCAN t2
}
# ^^^^^^^^^^^^^^^^^^^^
# The query should be converted into:
#   SELECT (SELECT count(*) FROM t1)+(SELECT count(*) FROM t2)

# 2023-05-09 https://sqlite.org/forum/forumpost/a7d4be7fb6
# Restriction (9) on the push-down optimization.
# 
reset_db
db null -
do_execsql_test 4.1 {
  CREATE TABLE t1(a INT);
  CREATE TABLE t2(b INT);
  CREATE TABLE t3(c INT);
  INSERT INTO t3(c) VALUES(3);
  CREATE TABLE t4(d INT);
  CREATE TABLE t5(e INT);
  INSERT INTO t5(e) VALUES(5);
  CREATE VIEW v6(f,g) AS SELECT d, e FROM t4 RIGHT JOIN t5 ON true;
  SELECT * FROM  t1 JOIN t2 ON false RIGHT JOIN t3 ON true CROSS JOIN v6;
} {- - 3 - 5}
do_execsql_test 4.2 {
  SELECT * FROM v6 JOIN t5 ON false RIGHT JOIN t3 ON true;
} {- - - 3}
do_execsql_test 4.3 {
  SELECT * FROM t1 JOIN t2 ON false JOIN v6 ON true RIGHT JOIN t3 ON true;
} {- - - - 3}

finish_test