From f570f011ebb27fece3bc44eec067dbab8b0a337a Mon Sep 17 00:00:00 2001 From: drh Date: Fri, 31 May 2002 15:51:25 +0000 Subject: [PATCH] Refinements to NULL processing: NULLs are indistinct for DISTINCT and UNION. Multiplying a NULL by zero yields zero. In a CASE expression, a NULL comparison is considered false, not NULL. With these changes, NULLs in SQLite now work the same as in PostgreSQL and in Oracle. (CVS 600) FossilOrigin-Name: da61aa1d238539dff9c43fd9f464d311e28d669f --- manifest | 27 +++---- manifest.uuid | 2 +- src/expr.c | 28 ++----- src/func.c | 6 +- src/select.c | 13 +++- src/util.c | 9 ++- src/vdbe.c | 27 ++++++- test/expr.test | 12 +-- test/minmax.test | 16 +++- test/null.test | 183 ++++++++++++++++++++++++++++++++++++++++++++++ test/select4.test | 15 ++-- 11 files changed, 279 insertions(+), 59 deletions(-) create mode 100644 test/null.test diff --git a/manifest b/manifest index 63b68ba4be..00c200d7f1 100644 --- a/manifest +++ b/manifest @@ -1,5 +1,5 @@ -C Once\sit\sis\sopened,\sleave\sthe\scheckpoint\sjournal\sfile\sopen\sfor\sthe\nduration\sof\sa\stransaction,\srather\sthan\sclosing\sit\sand\sreopening\sit\nfor\seach\sstatement.\s\s(Ticket\s#53)\s(CVS\s599) -D 2002-05-30T12:27:03 +C Refinements\sto\sNULL\sprocessing:\sNULLs\sare\sindistinct\sfor\sDISTINCT\sand\sUNION.\nMultiplying\sa\sNULL\sby\szero\syields\szero.\sIn\sa\sCASE\sexpression,\sa\sNULL\scomparison\nis\sconsidered\sfalse,\snot\sNULL.\s\sWith\sthese\schanges,\sNULLs\sin\sSQLite\snow\swork\nthe\ssame\sas\sin\sPostgreSQL\sand\sin\sOracle.\s(CVS\s600) +D 2002-05-31T15:51:25 F Makefile.in 6291a33b87d2a395aafd7646ee1ed562c6f2c28c F Makefile.template 4e11752e0b5c7a043ca50af4296ec562857ba495 F README a4c0ba11354ef6ba0776b400d057c59da47a4cc0 @@ -23,8 +23,8 @@ F src/btree.h 8abeabfe6e0b1a990b64fa457592a6482f6674f3 F src/build.c 36e42718a7a94f554ea39508993378482f5335c7 F src/delete.c a2b098cbbf518e6b641847e26de85827793bc523 F src/encode.c 346b12b46148506c32038524b95c4631ab46d760 -F src/expr.c 86f0c6f26f8b573883ba3219bd91bac5d4618f6b -F src/func.c 2cd4922913234ad384ccb75dd41bc35259a8338c +F src/expr.c 6bb74762c3d86b1665b32a6a388a70eeaaca93f8 +F src/func.c 061a520a122da7e4f9dcac15697bb996aac7d5df F src/hash.c 6a6236b89c8c060c65dabd300a1c8ce7c10edb72 F src/hash.h dca065dda89d4575f3176e75e9a3dc0f4b4fb8b9 F src/insert.c 24b4e146319bada6f82a1d5eae6b38b3065d132f @@ -37,7 +37,7 @@ F src/pager.h 6fddfddd3b73aa8abc081b973886320e3c614f0e F src/parse.y c681da701bf142967325b8791f22418e2d81552d F src/printf.c d8032ee18b860c812eeff596c9bebfdacb7930fd F src/random.c 19e8e00fe0df32a742f115773f57651be327cabe -F src/select.c 6e84ac2be582382a4d9a81b9594456bb46babb1c +F src/select.c 9a9f76d7d647284f41616bc120003961bea403ef F src/shell.c 1d22fe870ee852cfb975fd000dbe3973713d0a15 F src/shell.tcl 27ecbd63dd88396ad16d81ab44f73e6c0ea9d20e F src/sqlite.h.in 0038faa6d642de06b91143ee65a131bd831d020b @@ -51,8 +51,8 @@ F src/threadtest.c 81f0598e0f031c1bd506af337fdc1b7e8dff263f F src/tokenize.c facec7dc0b4a13e17ad67702f548dac2f7c6a732 F src/trigger.c d02f8e3510c7c2ad948a0e8c3bb0cca8adaf80c5 F src/update.c f68375173bf5338cae3e97012708e10f206aedd9 -F src/util.c a9f6e6f03e8b7137204ac15b35a58f321e38037e -F src/vdbe.c ccbee9fb9b98a2fc75400865d69531da36cbf0f1 +F src/util.c 7cf46b5612f5d12601c697374b9c6b38b2332ce8 +F src/vdbe.c 81ae0a1ce59d56fd4180cb8b20018c67b43d0423 F src/vdbe.h b8706429131c14b307a07aab7e47f95a9da53610 F src/where.c b054f2f23127bd57eb5f973bcd38764b875d73fe F test/all.test e4d3821eeba751829b419cd47814bd20af4286d1 @@ -63,7 +63,7 @@ F test/btree3.test 9caa9e22491dd8cd8aa36d7ac3b48b089817c895 F test/conflict.test 5149646703d3930c9111068b5cda7e2e938476e3 F test/copy.test b3cefcb520c64d7e7dfedbab06b4d4c31fa5b99a F test/delete.test c904a62129fe102b314a96111a8417f10249e4d8 -F test/expr.test 6a863adedb51b07fec745319aa6a1f939fbe0579 +F test/expr.test c61a92f7d76d63d7379d58bc35245e156c9b63c3 F test/func.test 628ab513b0d9c54251a63e026a26b7b4347e54ab F test/in.test c09312672e3f0709fa02c8e2e9cd8fb4bd6269aa F test/index.test c8a471243bbf878974b99baf5badd59407237cf3 @@ -76,10 +76,11 @@ F test/limit.test 6f98bcefc92209103bb3764c81975a6ec21d6702 F test/lock.test 3fcfd46a73119f6a18094673328a32c7b3047a8f F test/main.test c66b564554b770ee7fdbf6a66c0cd90329bc2c85 F test/malloc.test 7ba32a9ebd3aeed52ae4aaa6d42ca37e444536fd -F test/minmax.test a234053455ffd42d785ba6edc5425374e064ff0d +F test/minmax.test 29bc5727c3e4c792d5c4745833dd4b505905819e F test/misc1.test df281e9b26cd1db5808939c7cf2703072d555be0 F test/misuse.test a3aa2b18a97e4c409a1fcaff5151a4dd804a0162 F test/notnull.test b1f3e42fc475b0b5827b27b2e9b562081995ff30 +F test/null.test 732b4ec96e1c1a10b2bc3e1008c8f1da1cc0fb30 F test/pager.test b0c0d00cd5dce0ce21f16926956b195c0ab5044c F test/pragma.test 0b9675ef1f5ba5b43abfa337744445fc5b01a34a F test/printf.test 3cb415073754cb8ff076f26173143c3cd293a9da @@ -89,7 +90,7 @@ F test/rowid.test 4c55943300cddf73dd0f88d40a268cab14c83274 F test/select1.test a19a8026b5c2c5bdf5384d761f3d446954b7ebf9 F test/select2.test aceea74fd895b9d007512f72499db589735bd8e4 F test/select3.test 9469c332250a75a0ef1771fb5da62dc04ec77f18 -F test/select4.test 2ea8c7b7feceb853da167a39e4cce996a5c3ad88 +F test/select4.test 32018b97fde7202dcb906748836fcd79410604d3 F test/select5.test c2a6c4a003316ee42cbbd689eebef8fdce0db2ac F test/select6.test efb8d0c07a440441db87db2c4ade6904e1407e85 F test/sort.test 3b996ce7ca385f9cd559944ac0f4027a23aa546b @@ -135,7 +136,7 @@ F www/speed.tcl da8afcc1d3ccc5696cfb388a68982bc3d9f7f00f F www/sqlite.tcl 8b5884354cb615049aed83039f8dfe1552a44279 F www/tclsqlite.tcl 1db15abeb446aad0caf0b95b8b9579720e4ea331 F www/vdbe.tcl 2013852c27a02a091d39a766bc87cff329f21218 -P 4debc8db929fdc201759ba211acdeadc4e30e8af -R d3c150a342080a50caa6809fc7ad7e65 +P 7a24336d50e72006b2cc0e4feb292b946e79d5f3 +R fa5694968411297d416326c538e47fd0 U drh -Z 7c9293e04df21e05a0d63344cf0a4066 +Z 4ea8ccf14bc3e954bee7c679e23f1161 diff --git a/manifest.uuid b/manifest.uuid index 3ecef882a7..87ebcca7f6 100644 --- a/manifest.uuid +++ b/manifest.uuid @@ -1 +1 @@ -7a24336d50e72006b2cc0e4feb292b946e79d5f3 \ No newline at end of file +da61aa1d238539dff9c43fd9f464d311e28d669f \ No newline at end of file diff --git a/src/expr.c b/src/expr.c index 25f0ebd0bc..c414e39377 100644 --- a/src/expr.c +++ b/src/expr.c @@ -12,7 +12,7 @@ ** This file contains routines used for analyzing expressions and ** for generating VDBE code that evaluates expressions in SQLite. ** -** $Id: expr.c,v 1.65 2002/05/30 02:35:12 drh Exp $ +** $Id: expr.c,v 1.66 2002/05/31 15:51:25 drh Exp $ */ #include "sqliteInt.h" @@ -933,9 +933,7 @@ void sqliteExprCode(Parse *pParse, Expr *pExpr){ } case TK_CASE: { int expr_end_label; - int null_result_label; int jumpInst; - int nullBypassInst; int addr; int nExpr; int i; @@ -945,44 +943,32 @@ void sqliteExprCode(Parse *pParse, Expr *pExpr){ assert(pExpr->pList->nExpr > 0); nExpr = pExpr->pList->nExpr; expr_end_label = sqliteVdbeMakeLabel(v); - null_result_label = sqliteVdbeMakeLabel(v); if( pExpr->pLeft ){ sqliteExprCode(pParse, pExpr->pLeft); - nullBypassInst = sqliteVdbeAddOp(v, OP_IsNull, -1, 0); } for(i=0; ipList->a[i].pExpr); - sqliteVdbeAddOp(v, OP_IsNull, -1, null_result_label); if( pExpr->pLeft ){ sqliteVdbeAddOp(v, OP_Dup, 1, 1); - jumpInst = sqliteVdbeAddOp(v, OP_Ne, 0, 0); + jumpInst = sqliteVdbeAddOp(v, OP_Ne, 1, 0); + sqliteVdbeAddOp(v, OP_Pop, 1, 0); }else{ - jumpInst = sqliteVdbeAddOp(v, OP_IfNot, 0, 0); + jumpInst = sqliteVdbeAddOp(v, OP_IfNot, 1, 0); } sqliteExprCode(pParse, pExpr->pList->a[i+1].pExpr); sqliteVdbeAddOp(v, OP_Goto, 0, expr_end_label); - if( i>=nExpr-2 ){ - sqliteVdbeResolveLabel(v, null_result_label); - sqliteVdbeAddOp(v, OP_Pop, 1, 0); - if( pExpr->pRight!=0 ){ - sqliteVdbeAddOp(v, OP_String, 0, 0); - sqliteVdbeAddOp(v, OP_Goto, 0, expr_end_label); - } - } addr = sqliteVdbeCurrentAddr(v); sqliteVdbeChangeP2(v, jumpInst, addr); } + if( pExpr->pLeft ){ + sqliteVdbeAddOp(v, OP_Pop, 1, 0); + } if( pExpr->pRight ){ sqliteExprCode(pParse, pExpr->pRight); }else{ sqliteVdbeAddOp(v, OP_String, 0, 0); } sqliteVdbeResolveLabel(v, expr_end_label); - if( pExpr->pLeft ){ - sqliteVdbeAddOp(v, OP_Pull, 1, 0); - sqliteVdbeAddOp(v, OP_Pop, 1, 0); - sqliteVdbeChangeP2(v, nullBypassInst, sqliteVdbeCurrentAddr(v)); - } } break; } diff --git a/src/func.c b/src/func.c index 8ba7db9de6..4295ea341b 100644 --- a/src/func.c +++ b/src/func.c @@ -16,7 +16,7 @@ ** sqliteRegisterBuildinFunctions() found at the bottom of the file. ** All other code has file scope. ** -** $Id: func.c,v 1.18 2002/05/29 23:22:23 drh Exp $ +** $Id: func.c,v 1.19 2002/05/31 15:51:25 drh Exp $ */ #include #include @@ -362,7 +362,7 @@ static void minStep(sqlite_func *context, int argc, const char **argv){ MinMaxCtx *p; p = sqlite_aggregate_context(context, sizeof(*p)); if( p==0 || argc<1 || argv[0]==0 ) return; - if( sqlite_aggregate_count(context)==1 || sqliteCompare(argv[0],p->z)<0 ){ + if( p->z==0 || sqliteCompare(argv[0],p->z)<0 ){ int len; if( p->z && p->z!=p->zBuf ){ sqliteFree(p->z); @@ -381,7 +381,7 @@ static void maxStep(sqlite_func *context, int argc, const char **argv){ MinMaxCtx *p; p = sqlite_aggregate_context(context, sizeof(*p)); if( p==0 || argc<1 || argv[0]==0 ) return; - if( sqlite_aggregate_count(context)==1 || sqliteCompare(argv[0],p->z)>0 ){ + if( p->z==0 || sqliteCompare(argv[0],p->z)>0 ){ int len; if( p->z && p->z!=p->zBuf ){ sqliteFree(p->z); diff --git a/src/select.c b/src/select.c index 4acee15f1a..5a97be8dda 100644 --- a/src/select.c +++ b/src/select.c @@ -12,7 +12,7 @@ ** This file contains C code routines that are called by the parser ** to handle SELECT statements in SQLite. ** -** $Id: select.c,v 1.88 2002/05/27 12:24:48 drh Exp $ +** $Id: select.c,v 1.89 2002/05/31 15:51:25 drh Exp $ */ #include "sqliteInt.h" @@ -326,7 +326,12 @@ static int selectInnerLoop( ** part of the result. */ if( distinct>=0 && pEList && pEList->nExpr>0 ){ - sqliteVdbeAddOp(v, OP_IsNull, -pEList->nExpr, sqliteVdbeCurrentAddr(v)+7); + /* For the purposes of the DISTINCT keyword to a SELECT, NULLs + ** are indistinct. This was confirmed by experiment in Oracle + ** and PostgreSQL. It seems contradictory, but it appears to be + ** true. + ** sqliteVdbeAddOp(v, OP_IsNull, -pEList->nExpr,sqliteVdbeCurrentAddr(v)+7); + */ sqliteVdbeAddOp(v, OP_MakeKey, pEList->nExpr, 1); sqliteVdbeAddOp(v, OP_Distinct, distinct, sqliteVdbeCurrentAddr(v)+3); sqliteVdbeAddOp(v, OP_Pop, pEList->nExpr+1, 0); @@ -358,7 +363,7 @@ static int selectInnerLoop( ** table iParm. */ if( eDest==SRT_Union ){ - sqliteVdbeAddOp(v, OP_MakeRecord, nColumn, 1); + sqliteVdbeAddOp(v, OP_MakeRecord, nColumn, 0); sqliteVdbeAddOp(v, OP_String, 0, 0); sqliteVdbeAddOp(v, OP_PutStrKey, iParm, 0); }else @@ -377,7 +382,7 @@ static int selectInnerLoop( ** the temporary table iParm. */ if( eDest==SRT_Except ){ - int addr = sqliteVdbeAddOp(v, OP_MakeRecord, nColumn, 1); + int addr = sqliteVdbeAddOp(v, OP_MakeRecord, nColumn, 0); sqliteVdbeAddOp(v, OP_NotFound, iParm, addr+3); sqliteVdbeAddOp(v, OP_Delete, iParm, 0); }else diff --git a/src/util.c b/src/util.c index 536f15816f..d14e6d3710 100644 --- a/src/util.c +++ b/src/util.c @@ -14,7 +14,7 @@ ** This file contains functions for allocating memory, comparing ** strings, and stuff like that. ** -** $Id: util.c,v 1.44 2002/05/26 21:34:58 drh Exp $ +** $Id: util.c,v 1.45 2002/05/31 15:51:25 drh Exp $ */ #include "sqliteInt.h" #include @@ -728,6 +728,13 @@ int sqliteSortCompare(const char *a, const char *b){ int isNumA, isNumB; while( res==0 && *a && *b ){ + if( a[1]==0 ){ + res = -1; + break; + }else if( b[1]==0 ){ + res = +1; + break; + } isNumA = sqliteIsNumber(&a[1]); isNumB = sqliteIsNumber(&b[1]); if( isNumA ){ diff --git a/src/vdbe.c b/src/vdbe.c index 19d7ed78d7..3cf545279c 100644 --- a/src/vdbe.c +++ b/src/vdbe.c @@ -30,7 +30,7 @@ ** But other routines are also provided to help in building up ** a program instruction by instruction. ** -** $Id: vdbe.c,v 1.150 2002/05/27 01:04:51 drh Exp $ +** $Id: vdbe.c,v 1.151 2002/05/31 15:51:26 drh Exp $ */ #include "sqliteInt.h" #include @@ -1769,9 +1769,28 @@ case OP_Remainder: { int nos = tos - 1; VERIFY( if( nos<0 ) goto not_enough_stack; ) if( ((aStack[tos].flags | aStack[nos].flags) & STK_Null)!=0 ){ + int resultType = STK_Null; + if( pOp->opcode==OP_Multiply ){ + /* Special case: multiplying NULL by zero gives a zero result, not a + ** NULL result as it would normally. */ + if( (aStack[tos].flags & (STK_Int|STK_Real))!=0 + || ((aStack[tos].flags & STK_Str)!=0 && isNumber(zStack[tos])) ){ + Integerify(p,tos); + if( aStack[tos].i==0 ){ + resultType = STK_Int; + aStack[nos].i = 0; + } + }else if( (aStack[nos].flags & (STK_Int|STK_Real))!=0 + || ((aStack[nos].flags & STK_Str)!=0 && isNumber(zStack[nos])) ){ + Integerify(p,nos); + if( aStack[nos].i==0 ){ + resultType = STK_Int; + } + } + } POPSTACK; Release(p, nos); - aStack[nos].flags = STK_Null; + aStack[nos].flags = resultType; }else if( (aStack[tos].flags & aStack[nos].flags & STK_Int)==STK_Int ){ int a, b; a = aStack[tos].i; @@ -2346,6 +2365,10 @@ case OP_NotNull: { ** created this way will not necessarily be distinct across runs. ** But they should be distinct for transient tables (created using ** OP_OpenTemp) which is what they are intended for. +** +** (Later:) The P2==1 option was intended to make NULLs distinct +** for the UNION operator. But I have since discovered that NULLs +** are indistinct for UNION. So this option is never used. */ case OP_MakeRecord: { char *zNewRecord; diff --git a/test/expr.test b/test/expr.test index 12d5a64c79..1acb06203d 100644 --- a/test/expr.test +++ b/test/expr.test @@ -11,7 +11,7 @@ # This file implements regression tests for SQLite library. The # focus of this file is testing expressions. # -# $Id: expr.test,v 1.23 2002/05/30 12:27:03 drh Exp $ +# $Id: expr.test,v 1.24 2002/05/31 15:51:26 drh Exp $ set testdir [file dirname $argv0] source $testdir/tester.tcl @@ -337,23 +337,23 @@ test_expr expr-case.1 {i1=1, i2=2} \ test_expr expr-case.2 {i1=2, i2=2} \ {CASE WHEN i1 = i2 THEN 'eq' ELSE 'ne' END} eq test_expr expr-case.3 {i1=NULL, i2=2} \ - {CASE WHEN i1 = i2 THEN 'eq' ELSE 'ne' END} {{}} + {CASE WHEN i1 = i2 THEN 'eq' ELSE 'ne' END} ne test_expr expr-case.4 {i1=2, i2=NULL} \ - {CASE WHEN i1 = i2 THEN 'eq' ELSE 'ne' END} {{}} + {CASE WHEN i1 = i2 THEN 'eq' ELSE 'ne' END} ne test_expr expr-case.5 {i1=2} \ {CASE i1 WHEN 1 THEN 'one' WHEN 2 THEN 'two' ELSE 'error' END} two test_expr expr-case.6 {i1=1} \ {CASE i1 WHEN 1 THEN 'one' WHEN NULL THEN 'two' ELSE 'error' END} one test_expr expr-case.7 {i1=2} \ - {CASE i1 WHEN 1 THEN 'one' WHEN NULL THEN 'two' ELSE 'error' END} {{}} + {CASE i1 WHEN 1 THEN 'one' WHEN NULL THEN 'two' ELSE 'error' END} error test_expr expr-case.8 {i1=3} \ - {CASE i1 WHEN 1 THEN 'one' WHEN NULL THEN 'two' ELSE 'error' END} {{}} + {CASE i1 WHEN 1 THEN 'one' WHEN NULL THEN 'two' ELSE 'error' END} error test_expr expr-case.9 {i1=3} \ {CASE i1 WHEN 1 THEN 'one' WHEN 2 THEN 'two' ELSE 'error' END} error test_expr expr-case.10 {i1=3} \ {CASE i1 WHEN 1 THEN 'one' WHEN 2 THEN 'two' END} {{}} test_expr expr-case.11 {i1=null} \ - {CASE i1 WHEN 1 THEN 'one' WHEN 2 THEN 'two' ELSE 3 END} {{}} + {CASE i1 WHEN 1 THEN 'one' WHEN 2 THEN 'two' ELSE 3 END} 3 test_expr expr-case.12 {i1=1} \ {CASE i1 WHEN 1 THEN null WHEN 2 THEN 'two' ELSE 3 END} {{}} test_expr expr-case.13 {i1=7} \ diff --git a/test/minmax.test b/test/minmax.test index 8d86f1f775..86ec8a60ad 100644 --- a/test/minmax.test +++ b/test/minmax.test @@ -13,7 +13,7 @@ # aggregate min() and max() functions and which are handled as # as a special case. # -# $Id: minmax.test,v 1.3 2002/05/29 23:22:23 drh Exp $ +# $Id: minmax.test,v 1.4 2002/05/31 15:51:26 drh Exp $ set testdir [file dirname $argv0] source $testdir/tester.tcl @@ -128,5 +128,19 @@ do_test minmax-4.1 { (SELECT * FROM t1 UNION SELECT NULL as 'x', NULL as 'y') } } {1 20} +do_test minmax-4.2 { + execsql { + SELECT y, sum(x) FROM + (SELECT null, y+1 FROM t1 UNION SELECT * FROM t1) + GROUP BY y ORDER BY y; + } +} {1 1 2 5 3 22 4 92 5 90 6 0} +do_test minmax-4.3 { + execsql { + SELECT y, count(x), count(*) FROM + (SELECT null, y+1 FROM t1 UNION SELECT * FROM t1) + GROUP BY y ORDER BY y; + } +} {1 1 1 2 2 3 3 4 5 4 8 9 5 5 6 6 0 1} finish_test diff --git a/test/null.test b/test/null.test new file mode 100644 index 0000000000..1f3fe7212d --- /dev/null +++ b/test/null.test @@ -0,0 +1,183 @@ +# 2001 September 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. +# +# This file implements tests for proper treatment of the special +# value NULL. +# + +set testdir [file dirname $argv0] +source $testdir/tester.tcl + +# Create a table and some data to work with. +# +do_test null-1.0 { + execsql { + begin; + create table t1(a,b,c); + insert into t1 values(1,0,0); + insert into t1 values(2,0,1); + insert into t1 values(3,1,0); + insert into t1 values(4,1,1); + insert into t1 values(5,null,0); + insert into t1 values(6,null,1); + insert into t1 values(7,null,null); + commit; + select * from t1; + } +} {1 0 0 2 0 1 3 1 0 4 1 1 5 {} 0 6 {} 1 7 {} {}} + +# Check for how arithmetic expressions handle NULL +# +do_test null-1.1 { + execsql { + select ifnull(a+b,99) from t1; + } +} {1 2 4 5 99 99 99} +do_test null-1.2 { + execsql { + select ifnull(b*c,99) from t1; + } +} {0 0 0 1 0 99 99} +do_test null-1.2.1 { + execsql { + select ifnull(c*b,99) from t1; + } +} {0 0 0 1 0 99 99} + +# Check to see how the CASE expression handles NULL values. The +# first WHEN for which the test expression is TRUE is selected. +# FALSE and UNKNOWN test expressions are skipped. +# +do_test null-2.1 { + execsql { + select ifnull(case when b<>0 then 1 else 0 end, 99) from t1; + } +} {0 0 1 1 0 0 0} +do_test null-2.2 { + execsql { + select ifnull(case when not b<>0 then 1 else 0 end, 99) from t1; + } +} {1 1 0 0 0 0 0} +do_test null-2.3 { + execsql { + select ifnull(case when b<>0 and c<>0 then 1 else 0 end, 99) from t1; + } +} {0 0 0 1 0 0 0} +do_test null-2.4 { + execsql { + select ifnull(case when not (b<>0 and c<>0) then 1 else 0 end, 99) from t1; + } +} {1 1 1 0 1 0 0} +do_test null-2.5 { + execsql { + select ifnull(case when b<>0 or c<>0 then 1 else 0 end, 99) from t1; + } +} {0 1 1 1 0 1 0} +do_test null-2.6 { + execsql { + select ifnull(case when not (b<>0 or c<>0) then 1 else 0 end, 99) from t1; + } +} {1 0 0 0 0 0 0} +do_test null-2.7 { + execsql { + select ifnull(case b when c then 1 else 0 end, 99) from t1; + } +} {1 0 0 1 0 0 0} +do_test null-2.8 { + execsql { + select ifnull(case c when b then 1 else 0 end, 99) from t1; + } +} {1 0 0 1 0 0 0} + +# Check to see that NULL values are ignored in aggregate functions. +# +do_test null-3.1 { + execsql { + select count(*), count(b), count(c), sum(b), sum(c), + avg(b), avg(c), min(b), max(b) from t1; + } +} {7 4 6 2 3 0.5 0.5 0 1} + +# Check to see how WHERE clauses handle NULL values. A NULL value +# is the same as UNKNOWN. The WHERE clause should only select those +# rows that are TRUE. FALSE and UNKNOWN rows are rejected. +# +do_test null-4.1 { + execsql { + select a from t1 where b<10 + } +} {1 2 3 4} +do_test null-4.2 { + execsql { + select a from t1 where not b>10 + } +} {1 2 3 4} +do_test null-4.3 { + execsql { + select a from t1 where b<10 or c=1; + } +} {1 2 3 4 6} +do_test null-4.4 { + execsql { + select a from t1 where b<10 and c=1; + } +} {2 4} +do_test null-4.5 { + execsql { + select a from t1 where not (b<10 and c=1); + } +} {1 3 5} + +# The DISTINCT keyword on a SELECT statement should treat NULL values +# as distinct +# +do_test null-5.1 { + execsql { + select distinct b from t1 order by b; + } +} {{} 0 1} + +# A UNION to two queries should treat NULL values +# as distinct +# +do_test null-6.1 { + execsql { + select b from t1 union select c from t1 order by c; + } +} {{} 0 1} + +# The UNIQUE constraint only applies to non-null values +# +do_test null-7.1 { + execsql { + create table t2(a, b unique on conflict ignore); + insert into t2 values(1,1); + insert into t2 values(2,null); + insert into t2 values(3,null); + insert into t2 values(4,1); + select a from t2; + } +} {1 2 3} +do_test null-7.2 { + execsql { + create table t3(a, b, c, unique(b,c) on conflict ignore); + insert into t3 values(1,1,1); + insert into t3 values(2,null,1); + insert into t3 values(3,null,1); + insert into t3 values(4,1,1); + select a from t3; + } +} {1 2 3} + + + +finish_test diff --git a/test/select4.test b/test/select4.test index cfa8eca8e7..dc412a058b 100644 --- a/test/select4.test +++ b/test/select4.test @@ -12,7 +12,7 @@ # focus of this file is testing UNION, INTERSECT and EXCEPT operators # in SELECT statements. # -# $Id: select4.test,v 1.8 2002/05/27 01:04:51 drh Exp $ +# $Id: select4.test,v 1.9 2002/05/31 15:51:26 drh Exp $ set testdir [file dirname $argv0] source $testdir/tester.tcl @@ -249,7 +249,8 @@ do_test select4-6.2 { } } {0 1 1 1 2 2 3 4 3 7 4 8 5 15} -# NULLs are distinct. Make sure the UNION operator recognizes this +# NULLs are indistinct for the UNION operator. +# Make sure the UNION operator recognizes this # do_test select4-6.3 { execsql { @@ -257,8 +258,8 @@ do_test select4-6.3 { SELECT 1 UNION SELECT 2 AS 'x' ORDER BY x; } -} {{} {} 1 2} -do_test select4-6.3 { +} {{} 1 2} +do_test select4-6.3.1 { execsql { SELECT NULL UNION ALL SELECT NULL UNION ALL SELECT 1 UNION ALL SELECT 2 AS 'x' @@ -266,7 +267,7 @@ do_test select4-6.3 { } } {{} {} 1 2} -# Make sure the DISTINCT keyword treats NULLs as DISTINCT +# Make sure the DISTINCT keyword treats NULLs as indistinct. # do_test select4-6.4 { execsql { @@ -281,7 +282,7 @@ do_test select4-6.5 { SELECT NULL, 1 UNION ALL SELECT NULL, 1 ); } -} {{} 1 {} 1} +} {{} 1} do_test select4-6.6 { execsql { SELECT DISTINCT * FROM ( @@ -296,7 +297,7 @@ do_test select4-6.7 { execsql { SELECT NULL EXCEPT SELECT NULL } -} {{}} +} {} # Make sure column names are correct when a compound select appears as