If terms of the WHERE clause require that the right table in a LEFT JOIN
not be a null row, then simplify the LEFT JOIN into an ordinary JOIN.
FossilOrigin-Name: 5b7abecc7ab8ccbbb8cb5e0f672e67625c2555ad03442efbf34cb395f5bb71a8
diff --git a/src/expr.c b/src/expr.c
index d2fad0f..0bb7a8d 100644
--- a/src/expr.c
+++ b/src/expr.c
@@ -5002,6 +5002,58 @@
}
/*
+** This is the Expr node callback for sqlite3ExprImpliesNotNullRow().
+** If the expression node requires that the table at pWalker->iCur
+** have a non-NULL column, then set pWalker->eCode to 1 and abort.
+*/
+static int impliesNotNullRow(Walker *pWalker, Expr *pExpr){
+ if( ExprHasProperty(pExpr, EP_FromJoin) ) return WRC_Prune;
+ switch( pExpr->op ){
+ case TK_ISNULL:
+ case TK_IS:
+ case TK_OR:
+ case TK_FUNCTION:
+ case TK_AGG_FUNCTION:
+ return WRC_Prune;
+ case TK_COLUMN:
+ case TK_AGG_COLUMN:
+ if( pWalker->u.iCur==pExpr->iTable ){
+ pWalker->eCode = 1;
+ return WRC_Abort;
+ }
+ return WRC_Prune;
+ default:
+ return WRC_Continue;
+ }
+}
+
+/*
+** Return true (non-zero) if expression p can only be true if at least
+** one column of table iTab is non-null. In other words, return true
+** if expression p will always be NULL or false if every column of iTab
+** is NULL.
+**
+** Terms of p that are marked with EP_FromJoin (and hence that come from
+** the ON or USING clauses of LEFT JOINS) are excluded from the analysis.
+**
+** This routine is used to check if a LEFT JOIN can be converted into
+** an ordinary JOIN. The p argument is the WHERE clause. If the WHERE
+** clause requires that some column of the right table of the LEFT JOIN
+** be non-NULL, then the LEFT JOIN can be safely converted into an
+** ordinary join.
+*/
+int sqlite3ExprImpliesNonNullRow(Expr *p, int iTab){
+ Walker w;
+ w.xExprCallback = impliesNotNullRow;
+ w.xSelectCallback = 0;
+ w.xSelectCallback2 = 0;
+ w.eCode = 0;
+ w.u.iCur = iTab;
+ sqlite3WalkExpr(&w, p);
+ return w.eCode;
+}
+
+/*
** An instance of the following structure is used by the tree walker
** to determine if an expression can be evaluated by reference to the
** index only, without having to do a search for the corresponding
diff --git a/src/select.c b/src/select.c
index ded0180..3919e1b 100644
--- a/src/select.c
+++ b/src/select.c
@@ -382,6 +382,28 @@
}
}
+/* Undo the work of setJoinExpr(). In the expression tree p, convert every
+** term that is marked with EP_FromJoin and iRightJoinTable==iTable into
+** an ordinary term that omits the EP_FromJoin mark.
+**
+** This happens when a LEFT JOIN is simplified into an ordinary JOIN.
+*/
+static void unsetJoinExpr(Expr *p, int iTable){
+ while( p ){
+ if( ExprHasProperty(p, EP_FromJoin) && p->iRightJoinTable==iTable ){
+ ExprClearProperty(p, EP_FromJoin);
+ }
+ if( p->op==TK_FUNCTION && p->x.pList ){
+ int i;
+ for(i=0; i<p->x.pList->nExpr; i++){
+ unsetJoinExpr(p->x.pList->a[i].pExpr, iTable);
+ }
+ }
+ unsetJoinExpr(p->pLeft, iTable);
+ p = p->pRight;
+ }
+}
+
/*
** This routine processes the join information for a SELECT statement.
** ON and USING clauses are converted into extra terms of the WHERE clause.
@@ -5175,13 +5197,29 @@
generateColumnNames(pParse, p);
}
- /* Try to flatten subqueries in the FROM clause up into the main query
+ /* Try to various optimizations (flattening subqueries, and strength
+ ** reduction of join operators) in the FROM clause up into the main query
*/
#if !defined(SQLITE_OMIT_SUBQUERY) || !defined(SQLITE_OMIT_VIEW)
for(i=0; !p->pPrior && i<pTabList->nSrc; i++){
struct SrcList_item *pItem = &pTabList->a[i];
Select *pSub = pItem->pSelect;
Table *pTab = pItem->pTab;
+
+ /* Convert LEFT JOIN into JOIN if there are terms of the right table
+ ** of the LEFT JOIN used in the WHERE clause.
+ */
+ if( (pItem->fg.jointype & JT_LEFT)!=0
+ && sqlite3ExprImpliesNonNullRow(p->pWhere, pItem->iCursor)
+ && OptimizationEnabled(db, SQLITE_SimplifyJoin)
+ ){
+ SELECTTRACE(0x100,pParse,p,
+ ("LEFT-JOIN simplifies to JOIN on term %d\n",i));
+ pItem->fg.jointype &= ~JT_LEFT;
+ unsetJoinExpr(p->pWhere, pItem->iCursor);
+ }
+
+ /* No futher action if this term of the FROM clause is no a subquery */
if( pSub==0 ) continue;
/* Catch mismatch in the declared columns of a view and the number of
diff --git a/src/sqliteInt.h b/src/sqliteInt.h
index 7c8cf12..216a500 100644
--- a/src/sqliteInt.h
+++ b/src/sqliteInt.h
@@ -1533,6 +1533,7 @@
#define SQLITE_Stat34 0x0800 /* Use STAT3 or STAT4 data */
/* TH3 expects the Stat34 ^^^^^^ value to be 0x0800. Don't change it */
#define SQLITE_PushDown 0x1000 /* The push-down optimization */
+#define SQLITE_SimplifyJoin 0x2000 /* Convert LEFT JOIN to JOIN */
#define SQLITE_AllOpts 0xffff /* All optimizations */
/*
@@ -3823,6 +3824,7 @@
int sqlite3ExprCompareSkip(Expr*, Expr*, int);
int sqlite3ExprListCompare(ExprList*, ExprList*, int);
int sqlite3ExprImpliesExpr(Parse*,Expr*, Expr*, int);
+int sqlite3ExprImpliesNonNullRow(Expr*,int);
void sqlite3ExprAnalyzeAggregates(NameContext*, Expr*);
void sqlite3ExprAnalyzeAggList(NameContext*,ExprList*);
int sqlite3ExprCoveredByIndex(Expr*, int iCur, Index *pIdx);