From: drh Date: Thu, 8 Sep 2005 20:37:43 +0000 (+0000) Subject: SUM returns NULL when it has no inputs. Ticket #1413. (CVS 2678) X-Git-Tag: version-3.6.10~3481 X-Git-Url: http://git.ipfire.org/?a=commitdiff_plain;h=c2bd913a408e919441a3987c7b0b4b0e54d2057d;p=thirdparty%2Fsqlite.git SUM returns NULL when it has no inputs. Ticket #1413. (CVS 2678) FossilOrigin-Name: 6281859425d39c11d82875301fefafad1f08416d --- diff --git a/manifest b/manifest index e4574786d9..71b2dc340d 100644 --- a/manifest +++ b/manifest @@ -1,5 +1,5 @@ -C A\sSUM()\sof\sall\sNULLs\sreturns\sNULL.\s\sA\sSUM()\sof\snothing\sreturn\s0.\nA\sSUM()\sof\sa\smixture\sof\sNULLs\sand\snumbers\sreturns\sthe\ssum\sof\sthe\nnumbers.\s\sTicket\s#1413.\s(CVS\s2677) -D 2005-09-08T19:45:58 +C SUM\sreturns\sNULL\swhen\sit\shas\sno\sinputs.\s\sTicket\s#1413.\s(CVS\s2678) +D 2005-09-08T20:37:43 F Makefile.in 12784cdce5ffc8dfb707300c34e4f1eb3b8a14f1 F Makefile.linux-gcc 06be33b2a9ad4f005a5f42b22c4a19dab3cbb5c7 F README 9c4e2d6706bdcc3efdd773ce752a8cdab4f90028 @@ -41,7 +41,7 @@ F src/date.c 7444b0900a28da77e57e3337a636873cff0ae940 F src/delete.c 16a0e19460b14d219f39ff5c7a9eef808aa1969c F src/experimental.c 50c1e3b34f752f4ac10c36f287db095c2b61766d F src/expr.c 38f1e135aa80dfc62e253c1e22dd6e194efd2d61 -F src/func.c ebf56befdbecb6570f3fbf42e6e414baf5e2049a +F src/func.c f63d417248808ff2632a3b576536abffcc21d858 F src/hash.c 2b1b13f7400e179631c83a1be0c664608c8f021f F src/hash.h 1b0c445e1c89ff2aaad9b4605ba61375af001e84 F src/insert.c 484c73bc1309f283a31baa0e114f3ee980536397 @@ -145,7 +145,7 @@ F test/enc2.test 76c13b8c00beaf95b15c152e95dab51292eb1f0d F test/enc3.test f6a5f0b7b7f3a88f030d3143729b87cd5c86d837 F test/expr.test 71b8cba7fe5c228147c93e530e098144565aaa46 F test/fkey1.test 153004438d51e6769fb1ce165f6313972d6263ce -F test/func.test e1f9489e76a1add3ffeecd02038edca130ba759b +F test/func.test 431f8e07a30aadf2a2a0c8c32f918a497bc4331d F test/hook.test f8605cde4c77b2c6a4a73723bf6c507796a64dda F test/in.test cead6165aebbe0d451bb2263a307173acfeb6240 F test/index.test 51e01a0928b4b61228917ddd8c6c0e2466547f6f @@ -199,9 +199,9 @@ F test/safety.test 907b64fee719554a3622853812af3886fddbbb4f F test/schema.test 21cbe7dac652f6d7eb058f3dec369bdbf46bbde6 F test/select1.test 480233d4f5a81d7d59a55e40d05084d97e57ecdf F test/select2.test f3c2678c3a9f3cf08ec4988a3845bda64be6d9e3 -F test/select3.test 551e25e97baf4ed3ec1d3d99776f936517938e60 +F test/select3.test 576df1a5cc5e01dadae9176384e2d506315afdcf F test/select4.test c239f516aa31f42f2ef7c6d7cd01105f08f934ca -F test/select5.test 2dcd382d1d416bf984cd3030ca9f386488a51ab1 +F test/select5.test cf5c42137d915b5e866c99d018be67dad9ebed75 F test/select6.test 21b72c56e7cbcefd063fdf9bc6c89342aedabccf F test/select7.test 1bf795b948c133a15a2a5e99d3270e652ec58ce6 F test/sort.test 0c33a8ae1c238377ad197387c3872175f40d3843 @@ -219,7 +219,7 @@ F test/threadtest2.c 97a830d53c24c42290501fdfba4a6e5bdd34748b F test/trace.test 9fd28695c463b90c2d32c387a432e01eb26e8ccf F test/trans.test 10506dc30305cfb8c4098359f7f6f64786f69c5e F test/trigger1.test 152aed5a1fa90709fe171f2ca501a6b7f7901479 -F test/trigger2.test f85ee0db543c6303a23f7037cd48534dbb2d1796 +F test/trigger2.test dea71f4b05e22896e72527278bc8ef71b7475bf2 F test/trigger3.test 9102fd3933db294dc654b5aee9edfe9e94f2b9e2 F test/trigger4.test 9615207f3746b1f3965113007869e45a895d2497 F test/trigger5.test 619391a3e9fc194081d22cefd830d811e7badf83 @@ -286,7 +286,7 @@ F www/fullscanb.gif f7c94cb227f060511f8909e10f570157263e9a25 F www/index-ex1-x-b.gif f9b1d85c3fa2435cf38b15970c7e3aa1edae23a3 F www/index.tcl 853525c11fb519dac801bcbbe0488c447e526e7b F www/indirect1b1.gif adfca361d2df59e34f9c5cac52a670c2bfc303a1 -F www/lang.tcl 422b21b899f6d84dd3fdd2d4b204061b6912efd2 +F www/lang.tcl 7fd48a2d1866a58bca4d43808aed991616bf198d F www/lockingv3.tcl f59b19d6c8920a931f096699d6faaf61c05db55f F www/mingw.tcl d96b451568c5d28545fefe0c80bee3431c73f69c F www/nulls.tcl ec35193f92485b87b90a994a01d0171b58823fcf @@ -306,7 +306,7 @@ F www/tclsqlite.tcl 3df553505b6efcad08f91e9b975deb2e6c9bb955 F www/vdbe.tcl 87a31ace769f20d3627a64fa1fade7fed47b90d0 F www/version3.tcl a99cf5f6d8bd4d5537584a2b342f0fb9fa601d8b F www/whentouse.tcl 97e2b5cd296f7d8057e11f44427dea8a4c2db513 -P 48f6a331efea419fe948cd366f9c60ae41edddfd -R 37364513cd59bb3038c4f5a7cd9fbfba +P 2e6230edfd651b40481ebad8aa01a22ac92ce80c +R a88a293bb05baabbecb6ecb073a9f526 U drh -Z 7b39a84184f0dd170c44b611c8879606 +Z d9f9df11ed266877677e4103d7412fad diff --git a/manifest.uuid b/manifest.uuid index 8a250969c4..85716b801c 100644 --- a/manifest.uuid +++ b/manifest.uuid @@ -1 +1 @@ -2e6230edfd651b40481ebad8aa01a22ac92ce80c \ No newline at end of file +6281859425d39c11d82875301fefafad1f08416d \ No newline at end of file diff --git a/src/func.c b/src/func.c index 7d0a73c15a..ed9133c350 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.109 2005/09/08 19:45:58 drh Exp $ +** $Id: func.c,v 1.110 2005/09/08 20:37:43 drh Exp $ */ #include "sqliteInt.h" #include @@ -842,12 +842,12 @@ static void sumStep(sqlite3_context *context, int argc, sqlite3_value **argv){ static void sumFinalize(sqlite3_context *context){ SumCtx *p; p = sqlite3_aggregate_context(context, 0); - if( p==0 ){ - sqlite3_result_int(context, 0); - }else if( p->seenFloat ){ - sqlite3_result_double(context, p->sum); - }else if( p->cnt>0 ){ - sqlite3_result_int64(context, (i64)p->sum); + if( p && p->cnt>0 ){ + if( p->seenFloat ){ + sqlite3_result_double(context, p->sum); + }else{ + sqlite3_result_int64(context, (i64)p->sum); + } } } static void avgFinalize(sqlite3_context *context){ diff --git a/test/func.test b/test/func.test index 01e6914ade..ea11fc30b5 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.39 2005/09/08 19:45:58 drh Exp $ +# $Id: func.test,v 1.40 2005/09/08 20:37:44 drh Exp $ set testdir [file dirname $argv0] source $testdir/tester.tcl @@ -513,14 +513,14 @@ do_test func-18.2 { } } {9902.0} -# The sum of nothing is 0. But the sum of all NULLs is NULL. +# The sum of nothing is NULL. But the sum of all NULLs is NULL. # do_test func-18.3 { execsql { DELETE FROM t5; SELECT sum(x) FROM t5; } -} {0} +} {{}} do_test func-18.4 { execsql { INSERT INTO t5 VALUES(NULL); diff --git a/test/select3.test b/test/select3.test index c9a6a90807..3aa605a6d2 100644 --- a/test/select3.test +++ b/test/select3.test @@ -12,7 +12,7 @@ # focus of this file is testing aggregate functions and the # GROUP BY and HAVING clauses of SELECT statements. # -# $Id: select3.test,v 1.15 2005/09/08 12:57:28 drh Exp $ +# $Id: select3.test,v 1.16 2005/09/08 20:37:44 drh Exp $ set testdir [file dirname $argv0] source $testdir/tester.tcl @@ -233,7 +233,7 @@ do_test select3-7.2 { execsql { SELECT a, sum(b) FROM t2 WHERE b=5; } -} {{} 0} +} {{} {}} finish_test diff --git a/test/select5.test b/test/select5.test index 01b737857c..ee227881b8 100644 --- a/test/select5.test +++ b/test/select5.test @@ -12,7 +12,7 @@ # focus of this file is testing aggregate functions and the # GROUP BY and HAVING clauses of SELECT statements. # -# $Id: select5.test,v 1.12 2005/09/08 10:37:01 drh Exp $ +# $Id: select5.test,v 1.13 2005/09/08 20:37:44 drh Exp $ set testdir [file dirname $argv0] source $testdir/tester.tcl @@ -118,7 +118,7 @@ do_test select5-4.5 { execsql { SELECT sum(x) FROM t1 WHERE x>100 } -} {0} +} {{}} # Some tests for queries with a GROUP BY clause but no aggregate functions. # diff --git a/test/trigger2.test b/test/trigger2.test index a15d4cc9e4..1a057e3d28 100644 --- a/test/trigger2.test +++ b/test/trigger2.test @@ -93,7 +93,8 @@ ifcapable subquery { BEGIN INSERT INTO rlog VALUES ( (SELECT coalesce(max(idx),0) + 1 FROM rlog), old.a, old.b, - (SELECT sum(a) FROM tbl), (SELECT sum(b) FROM tbl), + (SELECT coalesce(sum(a),0) FROM tbl), + (SELECT coalesce(sum(b),0) FROM tbl), new.a, new.b); END; @@ -101,7 +102,8 @@ ifcapable subquery { BEGIN INSERT INTO rlog VALUES ( (SELECT coalesce(max(idx),0) + 1 FROM rlog), old.a, old.b, - (SELECT sum(a) FROM tbl), (SELECT sum(b) FROM tbl), + (SELECT coalesce(sum(a),0) FROM tbl), + (SELECT coalesce(sum(b),0) FROM tbl), new.a, new.b); END; @@ -110,7 +112,8 @@ ifcapable subquery { BEGIN INSERT INTO clog VALUES ( (SELECT coalesce(max(idx),0) + 1 FROM clog), old.a, old.b, - (SELECT sum(a) FROM tbl), (SELECT sum(b) FROM tbl), + (SELECT coalesce(sum(a),0) FROM tbl), + (SELECT coalesce(sum(b),0) FROM tbl), new.a, new.b); END; } @@ -140,7 +143,8 @@ ifcapable subquery { BEGIN INSERT INTO rlog VALUES ( (SELECT coalesce(max(idx),0) + 1 FROM rlog), old.a, old.b, - (SELECT sum(a) FROM tbl), (SELECT sum(b) FROM tbl), + (SELECT coalesce(sum(a),0) FROM tbl), + (SELECT coalesce(sum(b),0) FROM tbl), 0, 0); END; @@ -148,7 +152,8 @@ ifcapable subquery { BEGIN INSERT INTO rlog VALUES ( (SELECT coalesce(max(idx),0) + 1 FROM rlog), old.a, old.b, - (SELECT sum(a) FROM tbl), (SELECT sum(b) FROM tbl), + (SELECT coalesce(sum(a),0) FROM tbl), + (SELECT coalesce(sum(b),0) FROM tbl), 0, 0); END; } @@ -172,7 +177,8 @@ ifcapable subquery { BEGIN INSERT INTO rlog VALUES ( (SELECT coalesce(max(idx),0) + 1 FROM rlog), 0, 0, - (SELECT sum(a) FROM tbl), (SELECT sum(b) FROM tbl), + (SELECT coalesce(sum(a),0) FROM tbl), + (SELECT coalesce(sum(b),0) FROM tbl), new.a, new.b); END; @@ -180,7 +186,8 @@ ifcapable subquery { BEGIN INSERT INTO rlog VALUES ( (SELECT coalesce(max(idx),0) + 1 FROM rlog), 0, 0, - (SELECT sum(a) FROM tbl), (SELECT sum(b) FROM tbl), + (SELECT coalesce(sum(a),0) FROM tbl), + (SELECT coalesce(sum(b),0) FROM tbl), new.a, new.b); END; } diff --git a/www/lang.tcl b/www/lang.tcl index 1c46b01385..36c187a067 100644 --- a/www/lang.tcl +++ b/www/lang.tcl @@ -1,7 +1,7 @@ # # Run this Tcl script to generate the lang-*.html files. # -set rcsid {$Id: lang.tcl,v 1.98 2005/08/28 17:00:26 drh Exp $} +set rcsid {$Id: lang.tcl,v 1.99 2005/09/08 20:37:44 drh Exp $} source common.tcl if {[llength $argv]>0} { @@ -1360,7 +1360,8 @@ API.

- + @@ -1385,7 +1386,15 @@ if all values in the group are NULL. - +
avg(X)Return the average value of all X within a group.Return the average value of all non-NULL X within a +group. Non-numeric values are interpreted as 0.
sum(X)Return the numeric sum of all values in the group.Return the numeric sum of all numeric values in the group. + If there are no input rows or all values are NULL, then NULL is returned. + NULL is not a helpful result in that case (the correct answer should be + zero) but it is what the SQL standard requires and how + most other SQL database engines operate so SQLite does it that way + in order to be compatible. + You will probably want to use + "coalesce(sum(X),0)" instead of just "sum(X)" + to work around this design problem in the SQL language.
}