From 9eb516c0eb6ea0bee233af1b30e04eda0b6605de Mon Sep 17 00:00:00 2001 From: drh Date: Sun, 18 Jul 2004 20:52:32 +0000 Subject: [PATCH] min() ignores NULL values. Ticket #800. (CVS 1802) FossilOrigin-Name: 166234a2b61e1d6a501e48dde1caec0a02bec90b --- manifest | 24 ++++++++--------- manifest.uuid | 2 +- src/func.c | 11 +++++--- src/select.c | 10 +++++++- test/func.test | 6 ++--- test/minmax.test | 65 ++++++++++++++++++++++++++++++++++++++++++----- test/null.test | 2 +- test/select1.test | 4 +-- www/lang.tcl | 7 ++--- 9 files changed, 97 insertions(+), 34 deletions(-) diff --git a/manifest b/manifest index 56e9a12849..a37ac27009 100644 --- a/manifest +++ b/manifest @@ -1,5 +1,5 @@ -C mprintf()\scorrectly\shandles\s"%s","".\s\sFix\sfor\sticket\s#812.\s(CVS\s1800) -D 2004-07-17T21:56:10 +C min()\signores\sNULL\svalues.\s\sTicket\s#800.\s(CVS\s1802) +D 2004-07-18T20:52:32 F Makefile.in 77d1219b6563476711a7a962e865979a6f314eb0 F Makefile.linux-gcc a9e5a0d309fa7c38e7c14d3ecf7690879d3a5457 F README f1de682fbbd94899d50aca13d387d1b3fd3be2dd @@ -33,7 +33,7 @@ F src/date.c b3e8b2bef1e3f2ce24e5b057203036defb18c3f1 F src/delete.c e81545e546f6bc87d7508a93a09ca70695265af3 F src/encode.c a876af473d1d636faa3dca51c7571f2e007eea37 F src/expr.c d8ee92a9c11113a013f7853acb55453a8e0b2e92 -F src/func.c 5a15cfb0f1d9e5abbd42407205d5d6e2b0c09fb2 +F src/func.c f4a69379de4109d8c07b1d57f7e983de9b2275f6 F src/hash.c f0a2f22c2a7052d67053b5f4690ea3010bb3fb9f F src/hash.h 762d95f1e567664d1eafc1687de755626be962fb F src/insert.c d99ffe87e1e1397f4233afcd06841d52d6b17b18 @@ -56,7 +56,7 @@ F src/parse.y 51c8e696276c409618e66a4ccf316fcff245506e F src/pragma.c 8326df8c400f573eb43004dfb8e53e5102acb3e4 F src/printf.c 36090f6d7b4946539de97c1850675ce55ef66c16 F src/random.c eff68e3f257e05e81eae6c4d50a51eb88beb4ff3 -F src/select.c f02a65af34231031896e8442161cb5251e191e75 +F src/select.c d92ac2324218633a489c1c2090bb7ef1fe8a7fae F src/shell.c ebec5da57ea401f4886eefc790917b939d94d595 F src/sqlite.h.in aaf46c8d458efd8aca694ec4f18c6ecf616ee55e F src/sqliteInt.h aeae6793d1db335ec1179ad9f26b0affc0ec658a @@ -113,7 +113,7 @@ F test/enc2.test 7a60971a62748be6b607b4b4380eb4c5e151a6ec F test/enc3.test 2ae80b11adf5b2c171d2e17214dabd356b9672c1 F test/expr.test b4e945265c4c697bf5213b72558914ba10a989cc F test/fkey1.test d65c824459916249bee501532d6154ddab0b5db7 -F test/func.test 7653394d854a8e3eb97c7f03c39610f8dc23922b +F test/func.test d47ff9da6cdc2c7c5e56733678c17e98a4630ee3 F test/hook.test f8605cde4c77b2c6a4a73723bf6c507796a64dda F test/in.test b92a2df9162e1cbd33c6449a29a05e6955b1741a F test/index.test b6941dd532815f278042b85f79b1a6dc16c4d729 @@ -133,13 +133,13 @@ F test/main.test e8c4d9ca6d1e5f5e55e6550d31aec488883b2ed9 F test/malloc.test 769b240d89a7ef3320d88919fdb6765f9395a51f F test/memdb.test b8a13fa79f006bd087bbcf135ce8eb62056a6027 F test/memleak.test 26571a04575461f39a7cf97a2ee2f7fb2f519ddb -F test/minmax.test 3f87d1d49f7e9aa9ae80d35c47a1f5b034557899 +F test/minmax.test 82fa0957d4a42d1d4c0d52e3f8f579da064ce890 F test/misc1.test a8eb48d38f7a64e75314a2946db68d2b77901b7d F test/misc2.test 703734f5817215ca54e364833b3bf5ff36fcc21e F test/misc3.test eb488314990bfc0959221a1acc465013238bf168 F test/misuse.test 2a64ce711419f2fd12806ed95af930fd4e7bb8f3 F test/notnull.test 7a08117a71e74b0321aaa937dbeb41a09d6eb1d0 -F test/null.test 64730a1c32955e5cc510b7632fed6b9929a4029a +F test/null.test c14d0f4739f21e929b8115b72bf0c765b6bb1721 F test/pager.test 059cc5c58d3b5a851343dff8c56cf7286425d03a F test/pager2.test 55469c7c1c1a54d6b32d7b3cc99001e90101a1ce F test/pragma.test 212d810e02a51c0ff9784a19d55e35d23382005d @@ -149,7 +149,7 @@ F test/quick.test bbe4abf7f434d71c0de26626c8cbb4858e1bcb18 F test/quote.test 08f23385c685d3dc7914ec760d492cacea7f6e3d F test/rollback.test 4097328d44510277244ef4fa51b22b2f11d7ef4c F test/rowid.test b3d059f5c8d8874fa1c31030e0636f67405d20ea -F test/select1.test 813a270ac7996b31ff228e8109cd2d1e8c3fa255 +F test/select1.test 84b0d95f8bd0f5aaf695c08fdae7afc04b569436 F test/select2.test 91a2225926039b0d1687840735c284dbbf89f0bc F test/select3.test ab2e583154ee230fa4b46b06512775a38cd9d8b0 F test/select4.test 86e72fc3b07de4fe11439aa419e37db3c49467e2 @@ -218,7 +218,7 @@ F www/faq.tcl 3a1776818d9bd973ab0c3048ec7ad6b1ad091ae5 F www/fileformat.tcl f71a06a0d533c7df408539c64113b4adeaf29764 F www/formatchng.tcl d1dfecedfb25e122ab513a1e0948b15cb4f0be46 F www/index.tcl 963cc54d5ad111de44e1af7f2a22ab2ec152095d -F www/lang.tcl 5193e27d5ab92ffa98427ef0fcc55d7a7c0e3ac3 +F www/lang.tcl b2ba401104a76e7842469b33a968f5eda9bd462b F www/lockingv3.tcl afcd22f0f063989cff2f4d57bbc38d719b4c6e75 F www/mingw.tcl d96b451568c5d28545fefe0c80bee3431c73f69c F www/nulls.tcl f31330db8c978e675f5cd263067b32b822effa6f @@ -233,7 +233,7 @@ F www/tclsqlite.tcl 19191cf2a1010eaeff74c51d83fd5f5a4d899075 F www/vdbe.tcl 59288db1ac5c0616296b26dce071c36cb611dfe9 F www/version3.tcl 092a01f5ef430d2c4acc0ae558d74c4bb89638a0 F www/whentouse.tcl a8335bce47cc2fddb07f19052cb0cb4d9129a8e4 -P 1d30d0dd46c2bd12ce3f7dc06492f3e27ab6bcee -R a883873c22c5f6280ed24904f9fd2d42 +P 4f56db1149f65dc2edf6626fa20ae255a5f5280c +R beb886faf235c8b436ba8b6f603f6da8 U drh -Z 687b24d8f66905314c3d6818e3ab8a29 +Z dc319bd193fd8ef78827da98718764c0 diff --git a/manifest.uuid b/manifest.uuid index 22e5577537..9c9d9b041d 100644 --- a/manifest.uuid +++ b/manifest.uuid @@ -1 +1 @@ -4f56db1149f65dc2edf6626fa20ae255a5f5280c \ No newline at end of file +166234a2b61e1d6a501e48dde1caec0a02bec90b \ No newline at end of file diff --git a/src/func.c b/src/func.c index 023a42f92d..5843b41628 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.77 2004/06/28 13:09:11 danielk1977 Exp $ +** $Id: func.c,v 1.78 2004/07/18 20:52:32 drh Exp $ */ #include #include @@ -979,13 +979,16 @@ struct MinMaxCtx { ** Routines to implement min() and max() aggregate functions. */ static void minmaxStep(sqlite3_context *context, int argc, sqlite3_value **argv){ - int max = 0; - int cmp = 0; Mem *pArg = (Mem *)argv[0]; - Mem *pBest = (Mem *)sqlite3_aggregate_context(context, sizeof(*pBest)); + Mem *pBest; + + if( sqlite3_value_type(argv[0])==SQLITE_NULL ) return; + pBest = (Mem *)sqlite3_aggregate_context(context, sizeof(*pBest)); if( !pBest ) return; if( pBest->flags ){ + int max; + int cmp; CollSeq *pColl = sqlite3GetFuncCollSeq(context); /* This step function is used for both the min() and max() aggregates, ** the only difference between the two being that the sense of the diff --git a/src/select.c b/src/select.c index 9a7f762d8e..262ce4c512 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.195 2004/06/21 10:45:09 danielk1977 Exp $ +** $Id: select.c,v 1.196 2004/07/18 20:52:32 drh Exp $ */ #include "sqliteInt.h" @@ -2076,6 +2076,14 @@ static int simpleMinMaxQuery(Parse *pParse, Select *p, int eDest, int iParm){ sqlite3VdbeOp3(v, OP_OpenRead, base+1, pIdx->tnum, (char*)&pIdx->keyInfo, P3_KEYINFO); sqlite3VdbeAddOp(v, seekOp, base+1, 0); + if( seekOp==OP_Rewind ){ + int addr; + sqlite3VdbeAddOp(v, OP_SetNumColumns, base+1, pIdx->nColumn+1); + sqlite3VdbeAddOp(v, OP_KeyAsData, base+1, 1); + addr = sqlite3VdbeAddOp(v, OP_IdxColumn, base+1, 0); + sqlite3VdbeAddOp(v, OP_NotNull, 1, addr+3); + sqlite3VdbeAddOp(v, OP_Next, 1, addr); + } sqlite3VdbeAddOp(v, OP_IdxRecno, base+1, 0); sqlite3VdbeAddOp(v, OP_Close, base+1, 0); sqlite3VdbeAddOp(v, OP_MoveGe, base, 0); diff --git a/test/func.test b/test/func.test index 5dfee54054..717c6cc733 100644 --- a/test/func.test +++ b/test/func.test @@ -11,7 +11,7 @@ # This file implements regression tests for SQLite library. The # focus of this file is testing built-in functions. # -# $Id: func.test,v 1.27 2004/06/29 13:18:24 danielk1977 Exp $ +# $Id: func.test,v 1.28 2004/07/18 20:52:32 drh Exp $ set testdir [file dirname $argv0] source $testdir/tester.tcl @@ -251,7 +251,7 @@ do_test func-8.1 { execsql { SELECT sum(a), count(a), round(avg(a),2), min(a), max(a), count(*) FROM t2; } -} {68236 3 22745.33 {} 67890 5} +} {68236 3 22745.33 1 67890 5} do_test func-8.2 { execsql { SELECT max('z+'||a||'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOP') FROM t2; @@ -262,7 +262,7 @@ do_test func-8.3 { CREATE TEMP TABLE t3 AS SELECT a FROM t2 ORDER BY a DESC; SELECT min('z+'||a||'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOP') FROM t3; } -} {{}} +} {z+1abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOP} do_test func-8.4 { execsql { SELECT max('z+'||a||'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOP') FROM t3; diff --git a/test/minmax.test b/test/minmax.test index 3a32f76c7a..ae6275c336 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.10 2004/06/24 00:20:05 danielk1977 Exp $ +# $Id: minmax.test,v 1.11 2004/07/18 20:52:32 drh Exp $ set testdir [file dirname $argv0] source $testdir/tester.tcl @@ -127,7 +127,7 @@ do_test minmax-4.1 { SELECT coalesce(min(x+0),-1), coalesce(max(x+0),-1) FROM (SELECT * FROM t1 UNION SELECT NULL as 'x', NULL as 'y') } -} {-1 20} +} {1 20} do_test minmax-4.2 { execsql { SELECT y, sum(x) FROM @@ -276,9 +276,8 @@ do_test minmax-9.2 { } } {{}} -# If there is a NULL in an aggregate max(), ignore it. If a NULL -# occurs in an aggregate min(), then the result will be NULL because -# NULL compares less than all other values. +# If there is a NULL in an aggregate max() or min(), ignore it. An +# aggregate min() or max() will only return NULL if all values are NULL. # do_test minmax-10.1 { execsql { @@ -288,7 +287,7 @@ do_test minmax-10.1 { INSERT INTO t6 VALUES(NULL); SELECT coalesce(min(x),-1) FROM t6; } -} {-1} +} {1} do_test minmax-10.2 { execsql { SELECT max(x) FROM t6; @@ -299,11 +298,63 @@ do_test minmax-10.3 { CREATE INDEX i6 ON t6(x); SELECT coalesce(min(x),-1) FROM t6; } -} {-1} +} {1} do_test minmax-10.4 { execsql { SELECT max(x) FROM t6; } } {2} +do_test minmax-10.5 { + execsql { + DELETE FROM t6 WHERE x NOT NULL; + SELECT count(*) FROM t6; + } +} 1 +do_test minmax-10.6 { + execsql { + SELECT count(x) FROM t6; + } +} 0 +do_test minmax-10.7 { + execsql { + SELECT (SELECT min(x) FROM t6), (SELECT max(x) FROM t6); + } +} {{} {}} +do_test minmax-10.8 { + execsql { + SELECT min(x), max(x) FROM t6; + } +} {{} {}} +do_test minmax-10.9 { + execsql { + INSERT INTO t6 SELECT * FROM t6; + INSERT INTO t6 SELECT * FROM t6; + INSERT INTO t6 SELECT * FROM t6; + INSERT INTO t6 SELECT * FROM t6; + INSERT INTO t6 SELECT * FROM t6; + INSERT INTO t6 SELECT * FROM t6; + INSERT INTO t6 SELECT * FROM t6; + INSERT INTO t6 SELECT * FROM t6; + INSERT INTO t6 SELECT * FROM t6; + INSERT INTO t6 SELECT * FROM t6; + SELECT count(*) FROM t6; + } +} 1024 +do_test minmax-10.10 { + execsql { + SELECT count(x) FROM t6; + } +} 0 +do_test minmax-10.11 { + execsql { + SELECT (SELECT min(x) FROM t6), (SELECT max(x) FROM t6); + } +} {{} {}} +do_test minmax-10.12 { + execsql { + SELECT min(x), max(x) FROM t6; + } +} {{} {}} + finish_test diff --git a/test/null.test b/test/null.test index fdb8b17a2a..9705921715 100644 --- a/test/null.test +++ b/test/null.test @@ -100,7 +100,7 @@ do_test null-3.1 { 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 {} 1} +} {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 diff --git a/test/select1.test b/test/select1.test index c534acce23..53bd372a02 100644 --- a/test/select1.test +++ b/test/select1.test @@ -11,7 +11,7 @@ # This file implements regression tests for SQLite library. The # focus of this file is testing the SELECT statement. # -# $Id: select1.test,v 1.33 2004/06/24 00:20:05 danielk1977 Exp $ +# $Id: select1.test,v 1.34 2004/07/18 20:52:32 drh Exp $ set testdir [file dirname $argv0] source $testdir/tester.tcl @@ -159,7 +159,7 @@ do_test select1-2.8 { } {0 {11 33}} do_test select1-2.8.1 { execsql {SELECT coalesce(min(a),'xyzzy') FROM t3} -} {xyzzy} +} {11} do_test select1-2.8.2 { execsql {SELECT min(coalesce(a,'xyzzy')) FROM t3} } {11} diff --git a/www/lang.tcl b/www/lang.tcl index cd902ee844..aa699c0ed1 100644 --- a/www/lang.tcl +++ b/www/lang.tcl @@ -1,7 +1,7 @@ # # Run this Tcl script to generate the sqlite.html file. # -set rcsid {$Id: lang.tcl,v 1.70 2004/06/18 11:25:21 danielk1977 Exp $} +set rcsid {$Id: lang.tcl,v 1.71 2004/07/18 20:52:32 drh Exp $} source common.tcl header {Query Language Understood by SQLite} puts { @@ -1092,8 +1092,9 @@ The usual sort order is used to determine the maximum. min(X) -Return the minimum value of all values in the group. -The usual sort order is used to determine the minimum. +Return the minimum non-NULL value of all values in the group. +The usual sort order is used to determine the minimum. NULL is only returned +if all values in the group are NULL.