Many hyperlinks are disabled.
Use anonymous login
to enable hyperlinks.
Overview
Comment: | Attempt to optimize "x IS NULL" and "x IS NOT NULL" expressions when x is a column with a NOT NULL constraint. This addresses the performance issue described by forum post a5fc33cf9d8f4ff5. |
---|---|
Downloads: | Tarball | ZIP archive | SQL archive |
Timelines: | family | ancestors | descendants | both | trunk |
Files: | files | file ages | folders |
SHA3-256: |
de9c86c9e4cdb34f4b7d65f160d1e589 |
User & Date: | dan 2021-02-26 20:39:08 |
Original Comment: | Attempt to optimize "x IS NULL" and "x IS NOT NULL" expressions when x is a column with a NOT NULL constraint. |
References
2024-03-08
| ||
21:37 | The NOT NULL strength reduction optimization from [de9c86c9e4cdb34f] should be applied to the WHERE clause only. Otherwise, the operand of the IS NULL or IS NOT NULL operator might be a reference to a bare column of an aggregate table, and we can't tell if it is NULL or not based only on its NOT NULL attribute. Forum post 440f2a2f17. (check-in: 51704fea user: drh tags: trunk) | |
2023-03-03
| ||
16:25 | When it is known when preparing a statement that X cannot be NULL or is always NULL, transform the expression (X IS NULL) to integer value 1 or 0 instead of 'true' or 'false'. This is because under some circumstances, "Y IS TRUE" or "Y IS FALSE" may not be equivalent to "Y IS 1" of "Y IS 0". This problem was introduced by [de9c86c9e4cdb34f] and was reported by forum post 2cd11c2d37. (check-in: cc4bb05b user: dan tags: trunk) | |
2021-07-22
| ||
16:07 | One of the optimizations of check-in [de9c86c9e4cdb34f] does not work for terms originating in the ON/USING clause, as demonstrated by forum post 6cf3bb457c3f4685. This check-in disables that optimization for ON/USING terms. Also improve the TreeView display for the resulting "true"/"false" nodes to show that they originate from the ON/USING clause. Add a testcase() to the other optimization to show that it can still be used for ON/USING terms. (check-in: 1f679604 user: drh tags: trunk) | |
Context
2021-02-26
| ||
21:39 | Fix a segfault that could occur when optimizing a NOT NULL constraint against an IPK column of a sub-query. (check-in: e4d1970e user: dan tags: trunk) | |
20:39 | Attempt to optimize "x IS NULL" and "x IS NOT NULL" expressions when x is a column with a NOT NULL constraint. This addresses the performance issue described by forum post a5fc33cf9d8f4ff5. (check-in: de9c86c9 user: dan tags: trunk) | |
20:14 | Attempt to optimize "x IS NULL" and "x IS NOT NULL" expressions when x is a column with a NOT NULL constraint. (Closed-Leaf check-in: 5ecd8425 user: dan tags: ifnull-opt) | |
15:20 | Minor simplification in resolve.c. (check-in: 310dac34 user: dan tags: trunk) | |
Changes
Changes to src/resolve.c.
︙ | ︙ | |||
780 781 782 783 784 785 786 787 788 789 790 791 792 793 | pExpr->op = TK_COLUMN; pExpr->y.pTab = pItem->pTab; pExpr->iTable = pItem->iCursor; pExpr->iColumn--; pExpr->affExpr = SQLITE_AFF_INTEGER; break; } /* A column name: ID ** Or table name and column name: ID.ID ** Or a database, table and column: ID.ID.ID ** ** The TK_ID and TK_OUT cases are combined so that there will only ** be one call to lookupName(). Then the compiler will in-line | > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > | 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 | pExpr->op = TK_COLUMN; pExpr->y.pTab = pItem->pTab; pExpr->iTable = pItem->iCursor; pExpr->iColumn--; pExpr->affExpr = SQLITE_AFF_INTEGER; break; } /* An "<expr> IS NOT NULL" or "<expr> IS NULL". After resolving the ** LHS, check if there is a NOT NULL constraint in the schema that ** means the value of the expression can be determined immediately. ** If that is the case, replace the current expression node with ** a TK_TRUEFALSE node. ** ** If the node is replaced with a TK_TRUEFALSE node, then also restore ** the NameContext ref-counts to the state they where in before the ** LHS expression was resolved. This prevents the current select ** from being erroneously marked as correlated in some cases. */ case TK_NOTNULL: case TK_ISNULL: { int anRef[8]; NameContext *p; int i; for(i=0, p=pNC; p && i<ArraySize(anRef); p=p->pNext, i++){ anRef[i] = p->nRef; } sqlite3WalkExpr(pWalker, pExpr->pLeft); if( 0==sqlite3ExprCanBeNull(pExpr->pLeft) ){ if( pExpr->op==TK_NOTNULL ){ pExpr->u.zToken = "true"; ExprSetProperty(pExpr, EP_IsTrue); }else{ pExpr->u.zToken = "false"; ExprSetProperty(pExpr, EP_IsFalse); } pExpr->op = TK_TRUEFALSE; for(i=0, p=pNC; p && i<ArraySize(anRef); p=p->pNext, i++){ p->nRef = anRef[i]; } sqlite3ExprDelete(pParse->db, pExpr->pLeft); pExpr->pLeft = 0; } return WRC_Prune; } /* A column name: ID ** Or table name and column name: ID.ID ** Or a database, table and column: ID.ID.ID ** ** The TK_ID and TK_OUT cases are combined so that there will only ** be one call to lookupName(). Then the compiler will in-line |
︙ | ︙ |
Changes to src/select.c.
︙ | ︙ | |||
402 403 404 405 406 407 408 409 410 411 412 413 414 415 | ** 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) && (iTable<0 || 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); } } | > > > | 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 | ** 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) && (iTable<0 || p->iRightJoinTable==iTable) ){ ExprClearProperty(p, EP_FromJoin); } if( p->op==TK_COLUMN && p->iTable==iTable ){ ExprClearProperty(p, EP_CanBeNull); } 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); } } |
︙ | ︙ |
Changes to src/whereexpr.c.
︙ | ︙ | |||
1403 1404 1405 1406 1407 1408 1409 1410 1411 1412 1413 1414 1415 1416 | pNew->wtFlags |= exprCommute(pParse, pDup); pNew->leftCursor = aiCurCol[0]; pNew->u.x.leftColumn = aiCurCol[1]; testcase( (prereqLeft | extraRight) != prereqLeft ); pNew->prereqRight = prereqLeft | extraRight; pNew->prereqAll = prereqAll; pNew->eOperator = (operatorMask(pDup->op) + eExtraOp) & opMask; } } #ifndef SQLITE_OMIT_BETWEEN_OPTIMIZATION /* If a term is the BETWEEN operator, create two new virtual terms ** that define the range that the BETWEEN implements. For example: ** | > > > > > | 1403 1404 1405 1406 1407 1408 1409 1410 1411 1412 1413 1414 1415 1416 1417 1418 1419 1420 1421 | pNew->wtFlags |= exprCommute(pParse, pDup); pNew->leftCursor = aiCurCol[0]; pNew->u.x.leftColumn = aiCurCol[1]; testcase( (prereqLeft | extraRight) != prereqLeft ); pNew->prereqRight = prereqLeft | extraRight; pNew->prereqAll = prereqAll; pNew->eOperator = (operatorMask(pDup->op) + eExtraOp) & opMask; }else if( op==TK_ISNULL && 0==sqlite3ExprCanBeNull(pLeft) ){ pExpr->op = TK_TRUEFALSE; ExprSetProperty(pExpr, EP_IsFalse); pTerm->prereqAll = 0; pTerm->eOperator = 0; } } #ifndef SQLITE_OMIT_BETWEEN_OPTIMIZATION /* If a term is the BETWEEN operator, create two new virtual terms ** that define the range that the BETWEEN implements. For example: ** |
︙ | ︙ |
Added test/notnull2.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 | # 2021 February 15 # # 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. # #*********************************************************************** # This file implements regression tests for SQLite library. The # focus of this file is testing optimizations associated with "IS NULL" # and "IS NOT NULL" operators on columns with NOT NULL constraints. # set testdir [file dirname $argv0] source $testdir/tester.tcl set testprefix notnull2 do_execsql_test 1.0 { CREATE TABLE t1(a, b); CREATE TABLE t2(c, d NOT NULL); WITH x(i) AS ( SELECT 1 UNION ALL SELECT i+1 FROM x WHERE i<1000 ) INSERT INTO t1 SELECT i, i FROM x; INSERT INTO t2 SELECT * FROM t1; } proc do_vmstep_test {tn sql nstep {res {}}} { uplevel [list do_execsql_test $tn.0 $sql $res] set vmstep [db status vmstep] if {[string range $nstep 0 0]=="+"} { set body "if {$vmstep<$nstep} { error \"got $vmstep, expected more than [string range $nstep 1 end]\" }" } else { set body "if {$vmstep>$nstep} { error \"got $vmstep, expected less than $nstep\" }" } # set name "$tn.vmstep=$vmstep,expect=$nstep" set name "$tn.1" uplevel [list do_test $name $body {}] } do_vmstep_test 1.1.1 { SELECT * FROM t1 LEFT JOIN t2 WHERE a=c AND d IS NULL; } 100 {} do_vmstep_test 1.1.2 { SELECT * FROM t1 LEFT JOIN t2 WHERE a=c AND c IS NULL; } +1000 {} do_vmstep_test 1.2.1 { SELECT * FROM ( SELECT * FROM t2 ) WHERE d IS NULL } 100 {} do_vmstep_test 1.2.2 { SELECT * FROM ( SELECT * FROM t2 ) WHERE c IS NULL } +1000 {} do_vmstep_test 1.3.1 { SELECT * FROM t2 WHERE d IS NULL } 100 {} do_vmstep_test 1.3.2 { SELECT * FROM t2 WHERE c IS NULL } +1000 {} do_vmstep_test 1.4.1 { SELECT (d IS NOT NULL) FROM t2 WHERE 0==( d IS NOT NULL ) } 100 {} do_vmstep_test 1.4.2 { SELECT * FROM t2 WHERE 0==( c IS NOT NULL ) } +1000 {} do_vmstep_test 1.5.1 { SELECT count(*) FROM t2 WHERE EXISTS( SELECT t2.d IS NULL FROM t1 WHERE t1.a=450 ) } 10000 {1000} do_vmstep_test 1.5.2 { SELECT count(*) FROM t2 WHERE EXISTS( SELECT t2.c IS NULL FROM t1 WHERE t1.a=450 ) } +100000 {1000} finish_test |