SQLite

Check-in [1838a59c8a]
Login

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

Overview
Comment:An initial attempt to optimize VIEWs that occur as the right operand of a LEFT JOIN. This particular check-in does not work correctly because it does not deal with the case of columns in the VIEW that return non-NULL even when all columns in the table of the VIEW are NULL because of the LEFT JOIN.
Downloads: Tarball | ZIP archive
Timelines: family | ancestors | descendants | both | left-join-view
Files: files | file ages | folders
SHA3-256: 1838a59c8a1c151bd6fc822b0ffef661803cf0e4704c917e74a04567b81740b9
User & Date: drh 2017-04-14 17:18:45.647
Context
2017-04-14
19:03
Add the TK_IF_NULL_ROW opcode to deal with non-NULL result columns in the result set of a view or subquery on the RHS of a LEFT JOIN that gets flattened. (Closed-Leaf check-in: 3a5860d86f user: drh tags: left-join-view)
17:18
An initial attempt to optimize VIEWs that occur as the right operand of a LEFT JOIN. This particular check-in does not work correctly because it does not deal with the case of columns in the VIEW that return non-NULL even when all columns in the table of the VIEW are NULL because of the LEFT JOIN. (check-in: 1838a59c8a user: drh tags: left-join-view)
14:50
Make USE_FULLWARN=1 the default for MSVC and fix harmless compiler warnings. (check-in: 6bf673767b user: mistachkin tags: trunk)
Changes
Unified Diff Ignore Whitespace Patch
Changes to src/select.c.
3150
3151
3152
3153
3154
3155
3156

3157
3158
3159
3160
3161
3162
3163
**
** All references to columns in table iTable are to be replaced by corresponding
** expressions in pEList.
*/
typedef struct SubstContext {
  Parse *pParse;            /* The parsing context */
  int iTable;               /* Replace references to this table */

  ExprList *pEList;         /* Replacement expressions */
} SubstContext;

/* Forward Declarations */
static void substExprList(SubstContext*, ExprList*);
static void substSelect(SubstContext*, Select*, int);








>







3150
3151
3152
3153
3154
3155
3156
3157
3158
3159
3160
3161
3162
3163
3164
**
** All references to columns in table iTable are to be replaced by corresponding
** expressions in pEList.
*/
typedef struct SubstContext {
  Parse *pParse;            /* The parsing context */
  int iTable;               /* Replace references to this table */
  int iNewTable;            /* New table number, or -1 */
  ExprList *pEList;         /* Replacement expressions */
} SubstContext;

/* Forward Declarations */
static void substExprList(SubstContext*, ExprList*);
static void substSelect(SubstContext*, Select*, int);

3175
3176
3177
3178
3179
3180
3181



3182
3183
3184
3185
3186
3187
3188
** of the subquery rather the result set of the subquery.
*/
static Expr *substExpr(
  SubstContext *pSubst,  /* Description of the substitution */
  Expr *pExpr            /* Expr in which substitution occurs */
){
  if( pExpr==0 ) return 0;



  if( pExpr->op==TK_COLUMN && pExpr->iTable==pSubst->iTable ){
    if( pExpr->iColumn<0 ){
      pExpr->op = TK_NULL;
    }else{
      Expr *pNew;
      Expr *pCopy = pSubst->pEList->a[pExpr->iColumn].pExpr;
      assert( pSubst->pEList!=0 && pExpr->iColumn<pSubst->pEList->nExpr );







>
>
>







3176
3177
3178
3179
3180
3181
3182
3183
3184
3185
3186
3187
3188
3189
3190
3191
3192
** of the subquery rather the result set of the subquery.
*/
static Expr *substExpr(
  SubstContext *pSubst,  /* Description of the substitution */
  Expr *pExpr            /* Expr in which substitution occurs */
){
  if( pExpr==0 ) return 0;
  if( ExprHasProperty(pExpr, EP_FromJoin) && pExpr->iRightJoinTable==pSubst->iTable ){
    pExpr->iRightJoinTable = pSubst->iNewTable;
  }
  if( pExpr->op==TK_COLUMN && pExpr->iTable==pSubst->iTable ){
    if( pExpr->iColumn<0 ){
      pExpr->op = TK_NULL;
    }else{
      Expr *pNew;
      Expr *pCopy = pSubst->pEList->a[pExpr->iColumn].pExpr;
      assert( pSubst->pEList!=0 && pExpr->iColumn<pSubst->pEList->nExpr );
3281
3282
3283
3284
3285
3286
3287






3288
3289
3290
3291
3292
3293
3294
3295
**
**   (2)  The subquery is not an aggregate or (2a) the outer query is not a join
**        and (2b) the outer query does not use subqueries other than the one
**        FROM-clause subquery that is a candidate for flattening.  (2b is
**        due to ticket [2f7170d73bf9abf80] from 2015-02-09.)
**
**   (3)  The subquery is not the right operand of a left outer join






**        (Originally ticket #306.  Strengthened by ticket #3300)
**
**   (4)  The subquery is not DISTINCT.
**
**  (**)  At one point restrictions (4) and (5) defined a subset of DISTINCT
**        sub-queries that were excluded from this optimization. Restriction 
**        (4) has since been expanded to exclude all DISTINCT subqueries.
**







>
>
>
>
>
>
|







3285
3286
3287
3288
3289
3290
3291
3292
3293
3294
3295
3296
3297
3298
3299
3300
3301
3302
3303
3304
3305
**
**   (2)  The subquery is not an aggregate or (2a) the outer query is not a join
**        and (2b) the outer query does not use subqueries other than the one
**        FROM-clause subquery that is a candidate for flattening.  (2b is
**        due to ticket [2f7170d73bf9abf80] from 2015-02-09.)
**
**   (3)  The subquery is not the right operand of a left outer join
**        or (3b) the subquery is not a join and (3c) does not contain any
**        result-set columns that could be non-NULL even if columns of the
**        subquery table are NULL.
**        to be more restrictive - disallowing subquery if it was the
**        right operand of a left join.  See tickets #306 and #3300. Relaxed
**        to allow simple subqueries as the right operand of a left join
**        on 2017-04-14.)
**
**   (4)  The subquery is not DISTINCT.
**
**  (**)  At one point restrictions (4) and (5) defined a subset of DISTINCT
**        sub-queries that were excluded from this optimization. Restriction 
**        (4) has since been expanded to exclude all DISTINCT subqueries.
**
3399
3400
3401
3402
3403
3404
3405


3406
3407
3408
3409
3410
3411
3412
  Select *pParent;    /* Current UNION ALL term of the other query */
  Select *pSub;       /* The inner query or "subquery" */
  Select *pSub1;      /* Pointer to the rightmost select in sub-query */
  SrcList *pSrc;      /* The FROM clause of the outer query */
  SrcList *pSubSrc;   /* The FROM clause of the subquery */
  ExprList *pList;    /* The result set of the outer query */
  int iParent;        /* VDBE cursor number of the pSub result set temp table */


  int i;              /* Loop counter */
  Expr *pWhere;                    /* The WHERE clause */
  struct SrcList_item *pSubitem;   /* The subquery */
  sqlite3 *db = pParse->db;

  /* Check to see if flattening is permitted.  Return 0 if not.
  */







>
>







3409
3410
3411
3412
3413
3414
3415
3416
3417
3418
3419
3420
3421
3422
3423
3424
  Select *pParent;    /* Current UNION ALL term of the other query */
  Select *pSub;       /* The inner query or "subquery" */
  Select *pSub1;      /* Pointer to the rightmost select in sub-query */
  SrcList *pSrc;      /* The FROM clause of the outer query */
  SrcList *pSubSrc;   /* The FROM clause of the subquery */
  ExprList *pList;    /* The result set of the outer query */
  int iParent;        /* VDBE cursor number of the pSub result set temp table */
  int iNewParent = -1;/* Replacement table for iParent */
  int isLeftJoin = 0; /* True if pSub is the right side of a LEFT JOIN */    
  int i;              /* Loop counter */
  Expr *pWhere;                    /* The WHERE clause */
  struct SrcList_item *pSubitem;   /* The subquery */
  sqlite3 *db = pParse->db;

  /* Check to see if flattening is permitted.  Return 0 if not.
  */
3425
3426
3427
3428
3429
3430
3431
3432
3433
3434
3435
3436
3437
3438
3439
    if( (p->pWhere && ExprHasProperty(p->pWhere,EP_Subquery))
     || (sqlite3ExprListFlags(p->pEList) & EP_Subquery)!=0
     || (sqlite3ExprListFlags(p->pOrderBy) & EP_Subquery)!=0
    ){
      return 0;                                          /* Restriction (2b)  */
    }
  }
    
  pSubSrc = pSub->pSrc;
  assert( pSubSrc );
  /* Prior to version 3.1.2, when LIMIT and OFFSET had to be simple constants,
  ** not arbitrary expressions, we allowed some combining of LIMIT and OFFSET
  ** because they could be computed at compile-time.  But when LIMIT and OFFSET
  ** became arbitrary expressions, we were forced to add restrictions (13)
  ** and (14). */







|







3437
3438
3439
3440
3441
3442
3443
3444
3445
3446
3447
3448
3449
3450
3451
    if( (p->pWhere && ExprHasProperty(p->pWhere,EP_Subquery))
     || (sqlite3ExprListFlags(p->pEList) & EP_Subquery)!=0
     || (sqlite3ExprListFlags(p->pOrderBy) & EP_Subquery)!=0
    ){
      return 0;                                          /* Restriction (2b)  */
    }
  }

  pSubSrc = pSub->pSrc;
  assert( pSubSrc );
  /* Prior to version 3.1.2, when LIMIT and OFFSET had to be simple constants,
  ** not arbitrary expressions, we allowed some combining of LIMIT and OFFSET
  ** because they could be computed at compile-time.  But when LIMIT and OFFSET
  ** became arbitrary expressions, we were forced to add restrictions (13)
  ** and (14). */
3463
3464
3465
3466
3467
3468
3469
3470
3471
3472
3473
3474
3475
3476
3477
3478
3479
3480
3481
3482
3483
3484
3485
3486
3487
3488
3489
3490
3491
3492
3493
3494
3495
3496
3497
3498
3499
3500
3501
3502


3503



3504
3505
3506
3507
3508
3509
3510
  if( pSub->selFlags & (SF_Recursive|SF_MinMaxAgg) ){
    return 0; /* Restrictions (22) and (24) */
  }
  if( (p->selFlags & SF_Recursive) && pSub->pPrior ){
    return 0; /* Restriction (23) */
  }

  /* OBSOLETE COMMENT 1:
  ** Restriction 3:  If the subquery is a join, make sure the subquery is 
  ** not used as the right operand of an outer join.  Examples of why this
  ** is not allowed:
  **
  **         t1 LEFT OUTER JOIN (t2 JOIN t3)
  **
  ** If we flatten the above, we would get
  **
  **         (t1 LEFT OUTER JOIN t2) JOIN t3
  **
  ** which is not at all the same thing.
  **
  ** OBSOLETE COMMENT 2:
  ** Restriction 12:  If the subquery is the right operand of a left outer
  ** join, make sure the subquery has no WHERE clause.
  ** An examples of why this is not allowed:
  **
  **         t1 LEFT OUTER JOIN (SELECT * FROM t2 WHERE t2.x>0)
  **
  ** If we flatten the above, we would get
  **
  **         (t1 LEFT OUTER JOIN t2) WHERE t2.x>0
  **
  ** But the t2.x>0 test will always fail on a NULL row of t2, which
  ** effectively converts the OUTER JOIN into an INNER JOIN.
  **
  ** THIS OVERRIDES OBSOLETE COMMENTS 1 AND 2 ABOVE:
  ** Ticket #3300 shows that flattening the right term of a LEFT JOIN
  ** is fraught with danger.  Best to avoid the whole thing.  If the
  ** subquery is the right term of a LEFT JOIN, then do not flatten.
  */
  if( (pSubitem->fg.jointype & JT_OUTER)!=0 ){


    return 0;



  }

  /* Restriction 17: If the sub-query is a compound SELECT, then it must
  ** use only the UNION ALL operator. And none of the simple select queries
  ** that make up the compound SELECT are allowed to be aggregate or distinct
  ** queries.
  */







|
|
|
<









|
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<
<


>
>
|
>
>
>







3475
3476
3477
3478
3479
3480
3481
3482
3483
3484

3485
3486
3487
3488
3489
3490
3491
3492
3493
3494

















3495
3496
3497
3498
3499
3500
3501
3502
3503
3504
3505
3506
3507
3508
3509
  if( pSub->selFlags & (SF_Recursive|SF_MinMaxAgg) ){
    return 0; /* Restrictions (22) and (24) */
  }
  if( (p->selFlags & SF_Recursive) && pSub->pPrior ){
    return 0; /* Restriction (23) */
  }

  /*
  ** If the subquery is the right operand of a LEFT JOIN, then the
  ** subquery may not be a join itself.  Example of why this is not allowed:

  **
  **         t1 LEFT OUTER JOIN (t2 JOIN t3)
  **
  ** If we flatten the above, we would get
  **
  **         (t1 LEFT OUTER JOIN t2) JOIN t3
  **
  ** which is not at all the same thing.
  **
  ** See also tickets #306 and #3300.

















  */
  if( (pSubitem->fg.jointype & JT_OUTER)!=0 ){
    isLeftJoin = 1;
    if( pSubSrc->nSrc>1 ){
      return 0; /* Restriction (3b) */
    }
    /* TBD: Deal with the case of result-set expressions that are non-NULL even
    ** when the RHS table of a LEFT JOIN is NULL. */
  }

  /* Restriction 17: If the sub-query is a compound SELECT, then it must
  ** use only the UNION ALL operator. And none of the simple select queries
  ** that make up the compound SELECT are allowed to be aggregate or distinct
  ** queries.
  */
3705
3706
3707
3708
3709
3710
3711

3712
3713
3714
3715
3716
3717
3718
    /* Transfer the FROM clause terms from the subquery into the
    ** outer query.
    */
    for(i=0; i<nSubSrc; i++){
      sqlite3IdListDelete(db, pSrc->a[i+iFrom].pUsing);
      assert( pSrc->a[i+iFrom].fg.isTabFunc==0 );
      pSrc->a[i+iFrom] = pSubSrc->a[i];

      memset(&pSubSrc->a[i], 0, sizeof(pSubSrc->a[i]));
    }
    pSrc->a[iFrom].fg.jointype = jointype;
  
    /* Now begin substituting subquery result set expressions for 
    ** references to the iParent in the outer query.
    ** 







>







3704
3705
3706
3707
3708
3709
3710
3711
3712
3713
3714
3715
3716
3717
3718
    /* Transfer the FROM clause terms from the subquery into the
    ** outer query.
    */
    for(i=0; i<nSubSrc; i++){
      sqlite3IdListDelete(db, pSrc->a[i+iFrom].pUsing);
      assert( pSrc->a[i+iFrom].fg.isTabFunc==0 );
      pSrc->a[i+iFrom] = pSubSrc->a[i];
      iNewParent = pSubSrc->a[i].iCursor;
      memset(&pSubSrc->a[i], 0, sizeof(pSubSrc->a[i]));
    }
    pSrc->a[iFrom].fg.jointype = jointype;
  
    /* Now begin substituting subquery result set expressions for 
    ** references to the iParent in the outer query.
    ** 
3750
3751
3752
3753
3754
3755
3756



3757
3758
3759
3760
3761
3762
3763
3764
3765
3766
3767
3768
3769
3770
3771
3772

3773
3774
3775
3776
3777
3778
3779
      }
      assert( pParent->pOrderBy==0 );
      assert( pSub->pPrior==0 );
      pParent->pOrderBy = pOrderBy;
      pSub->pOrderBy = 0;
    }
    pWhere = sqlite3ExprDup(db, pSub->pWhere, 0);



    if( subqueryIsAgg ){
      assert( pParent->pHaving==0 );
      pParent->pHaving = pParent->pWhere;
      pParent->pWhere = pWhere;
      pParent->pHaving = sqlite3ExprAnd(db, 
          sqlite3ExprDup(db, pSub->pHaving, 0), pParent->pHaving
      );
      assert( pParent->pGroupBy==0 );
      pParent->pGroupBy = sqlite3ExprListDup(db, pSub->pGroupBy, 0);
    }else{
      pParent->pWhere = sqlite3ExprAnd(db, pWhere, pParent->pWhere);
    }
    if( db->mallocFailed==0 ){
      SubstContext x;
      x.pParse = pParse;
      x.iTable = iParent;

      x.pEList = pSub->pEList;
      substSelect(&x, pParent, 0);
    }
  
    /* The flattened query is distinct if either the inner or the
    ** outer query is distinct. 
    */







>
>
>
















>







3750
3751
3752
3753
3754
3755
3756
3757
3758
3759
3760
3761
3762
3763
3764
3765
3766
3767
3768
3769
3770
3771
3772
3773
3774
3775
3776
3777
3778
3779
3780
3781
3782
3783
      }
      assert( pParent->pOrderBy==0 );
      assert( pSub->pPrior==0 );
      pParent->pOrderBy = pOrderBy;
      pSub->pOrderBy = 0;
    }
    pWhere = sqlite3ExprDup(db, pSub->pWhere, 0);
    if( isLeftJoin ){
      setJoinExpr(pWhere, iNewParent);
    }
    if( subqueryIsAgg ){
      assert( pParent->pHaving==0 );
      pParent->pHaving = pParent->pWhere;
      pParent->pWhere = pWhere;
      pParent->pHaving = sqlite3ExprAnd(db, 
          sqlite3ExprDup(db, pSub->pHaving, 0), pParent->pHaving
      );
      assert( pParent->pGroupBy==0 );
      pParent->pGroupBy = sqlite3ExprListDup(db, pSub->pGroupBy, 0);
    }else{
      pParent->pWhere = sqlite3ExprAnd(db, pWhere, pParent->pWhere);
    }
    if( db->mallocFailed==0 ){
      SubstContext x;
      x.pParse = pParse;
      x.iTable = iParent;
      x.iNewTable = iNewParent;
      x.pEList = pSub->pEList;
      substSelect(&x, pParent, 0);
    }
  
    /* The flattened query is distinct if either the inner or the
    ** outer query is distinct. 
    */
3874
3875
3876
3877
3878
3879
3880

3881
3882
3883
3884
3885
3886
3887
  if( sqlite3ExprIsTableConstant(pWhere, iCursor) ){
    nChng++;
    while( pSubq ){
      SubstContext x;
      pNew = sqlite3ExprDup(pParse->db, pWhere, 0);
      x.pParse = pParse;
      x.iTable = iCursor;

      x.pEList = pSubq->pEList;
      pNew = substExpr(&x, pNew);
      pSubq->pWhere = sqlite3ExprAnd(pParse->db, pSubq->pWhere, pNew);
      pSubq = pSubq->pPrior;
    }
  }
  return nChng;







>







3878
3879
3880
3881
3882
3883
3884
3885
3886
3887
3888
3889
3890
3891
3892
  if( sqlite3ExprIsTableConstant(pWhere, iCursor) ){
    nChng++;
    while( pSubq ){
      SubstContext x;
      pNew = sqlite3ExprDup(pParse->db, pWhere, 0);
      x.pParse = pParse;
      x.iTable = iCursor;
      x.iNewTable = iCursor;
      x.pEList = pSubq->pEList;
      pNew = substExpr(&x, pNew);
      pSubq->pWhere = sqlite3ExprAnd(pParse->db, pSubq->pWhere, pNew);
      pSubq = pSubq->pPrior;
    }
  }
  return nChng;