From: drh Date: Thu, 9 Feb 2006 22:13:41 +0000 (+0000) Subject: SUM never gives an error. An integer result is returned for exact results X-Git-Tag: version-3.6.10~3101 X-Git-Url: http://git.ipfire.org/gitweb/gitweb.cgi?a=commitdiff_plain;h=29d7210819390ac89c9584ce248658d61787262e;p=thirdparty%2Fsqlite.git SUM never gives an error. An integer result is returned for exact results and a floating point result is returned for approximate results. Tickets #1664, #1669, and #1670. (CVS 3066) FossilOrigin-Name: 9e04f8fdf1ec0dc36effb55c05d075b3b4777fef --- diff --git a/manifest b/manifest index 29cb28ca88..a0476f9e78 100644 --- a/manifest +++ b/manifest @@ -1,5 +1,5 @@ -C Deprecate\sthe\ssqlite3_aggregate_count()\sAPI.\s\sMake\ssure\sall\saggregate\scounters\nare\s64\sbits.\s\sRemove\sunused\sStdDev\sstructure\sfrom\sfunc.c.\s\sTicket\s#1669.\s(CVS\s3065) -D 2006-02-09T18:35:30 +C SUM\snever\sgives\san\serror.\s\sAn\sinteger\sresult\sis\sreturned\sfor\sexact\sresults\nand\sa\sfloating\spoint\sresult\sis\sreturned\sfor\sapproximate\sresults.\nTickets\s#1664,\s#1669,\sand\s#1670.\s(CVS\s3066) +D 2006-02-09T22:13:42 F Makefile.in 5d8dff443383918b700e495de42ec65bc1c8865b F Makefile.linux-gcc 74ba0eadf88748a9ce3fd03d2a3ede2e6715baec F README 9c4e2d6706bdcc3efdd773ce752a8cdab4f90028 @@ -43,7 +43,7 @@ F src/date.c cd2bd5d1ebc6fa12d6312f69789ae5b0a2766f2e F src/delete.c 56ab34c3a384caa5d5ea06f5739944957e2e4213 F src/experimental.c 1b2d1a6cd62ecc39610e97670332ca073c50792b F src/expr.c 1149c3380bfce27703f5e9bec7dfb8e51baaf9d9 -F src/func.c 49f49131afb37d1f808e9b84029da8644fc4faf7 +F src/func.c 93d004b453a5d9aa754e673eef75d3c9527e0f54 F src/hash.c 8747cf51d12de46512880dfcf1b68b4e24072863 F src/hash.h 1b0c445e1c89ff2aaad9b4605ba61375af001e84 F src/insert.c 7e931b7f06afbcefcbbaab175c02eff8268db33f @@ -69,7 +69,7 @@ F src/random.c d40f8d356cecbd351ccfab6eaedd7ec1b54f5261 F src/select.c daee9b20702ba51cf3807fc1b130edd8846e3e48 F src/server.c 087b92a39d883e3fa113cae259d64e4c7438bc96 F src/shell.c 738f55ed75fb36731e764bfdb40756ac43b90b08 -F src/sqlite.h.in 57d43548b59eed5116a322fc85bef4e3fc8a6bcc +F src/sqlite.h.in 89120d384e949be60f36af0e9e9f1b2684a30d35 F src/sqliteInt.h 0121298397ac14eb468ab1ba9d488ac7ed7d88a1 F src/table.c 486dcfce532685b53b5a2b5da8bba0ded6fb2316 F src/tclsqlite.c 7764ab34df617b3d3cfd5f0fdf3444ed219c11d6 @@ -81,7 +81,7 @@ F src/test5.c 7162f8526affb771c4ed256826eee7bb9eca265f F src/test6.c 60a02961ceb7b3edc25f5dc5c1ac2556622a76de F src/test7.c d28d3e62f9594923648fc6a8fb030eba36564ba1 F src/test_async.c 6776f5027ca6378c116ff5ccc2fe41b908e33772 -F src/test_md5.c e688969fc7db0acd9e4f4e0c33332e00228af60f +F src/test_md5.c 6c42bc0a3c0b54be34623ff77a0eec32b2fa96e3 F src/test_server.c 087b92a39d883e3fa113cae259d64e4c7438bc96 F src/tokenize.c 9ae9a59238eb97fbc61baea280563b91100518fb F src/trigger.c 4d3644cbd16959b568c95ae73493402be8021b08 @@ -89,10 +89,10 @@ F src/update.c 14be4ba2f438919b4217085c02feff569e6cf1f2 F src/utf.c 1199766bbb0157931a83aa6eede6b6381177be64 F src/util.c 405f46fef062b476826d2c171ec21def29563b75 F src/vacuum.c 3865673cc66acd0717ecd517f6b8fdb2a5e7924b -F src/vdbe.c 29c68f39ce8cba44814b0e1f3d909ef961eb28a7 +F src/vdbe.c c92d7a4d3476136b8ab440f1e0547fab24112b34 F src/vdbe.h 8729a4ee16ff9aeab2af9667df3cf300ff978e13 F src/vdbeInt.h eb3f86ab08ef11635bc78eb88c3ff13f923c233b -F src/vdbeapi.c ee8e889d8b4df30e38cdcda63f4e9e515b292633 +F src/vdbeapi.c 54dfd0975151c859ec5b125d225ad5b3cb586497 F src/vdbeaux.c 9bf50cdb6a6c40b8c06ca9a8d87cf90120a16797 F src/vdbefifo.c 9efb94c8c3f4c979ebd0028219483f88e57584f5 F src/vdbemem.c 2034e93b32c14bda6e306bb54e3a8e930b963027 @@ -164,7 +164,7 @@ F test/enc3.test 890508efff6677345e93bf2a8adb0489b30df030 F test/expr.test 4e65cade931e14a0194eee41e33707e7af5f397a F test/fkey1.test 153004438d51e6769fb1ce165f6313972d6263ce F test/format4.test 9f31d41d4f926cab97b2ebe6be00a6ab12dece87 -F test/func.test 458898c38bbb94e59ba4d96eff05731579acec33 +F test/func.test ba6159745ecb0b1c7cb4b082b34d5b2b09270eec F test/hook.test 7e7645fd9a033f79cce8fdff151e32715e7ec50a F test/in.test 40feeebc7e38576255051aad428322be1545e0f1 F test/index.test c478459611ded74745fee57f99f424da8a5f5fbd @@ -221,7 +221,7 @@ F test/rollback.test 673cd8c44c685ad54987fe7f0eeba84efa09685d F test/rowid.test 040a3bef06f970c45f5fcd14b2355f7f4d62f0cf F test/safety.test 4a06934e45d03b8b50ebcd8d174eb0367d2fd851 F test/schema.test 8a2ae440fb15f5798a68059e8746402f3137be46 -F test/select1.test f4ab4b66e7089f0c64b6df954e75bafe05aabc0d +F test/select1.test 9991b12eb68fa86e0faa29f26f51986d80ce0c42 F test/select2.test f3c2678c3a9f3cf08ec4988a3845bda64be6d9e3 F test/select3.test 8fece41cd8f2955131b3f973a7123bec60b6e65e F test/select4.test c239f516aa31f42f2ef7c6d7cd01105f08f934ca @@ -329,7 +329,7 @@ F www/fullscanb.gif f7c94cb227f060511f8909e10f570157263e9a25 F www/index-ex1-x-b.gif f9b1d85c3fa2435cf38b15970c7e3aa1edae23a3 F www/index.tcl 9e31e3df4fe9385b24fb30086361c51a3ae486b5 F www/indirect1b1.gif adfca361d2df59e34f9c5cac52a670c2bfc303a1 -F www/lang.tcl 3f7472e77a8257fb7c61a14e7607de3005b3fa2d +F www/lang.tcl 8761d4ce0dfd029a638cfd4c54422dd852ec6606 F www/lockingv3.tcl f59b19d6c8920a931f096699d6faaf61c05db55f F www/mingw.tcl d96b451568c5d28545fefe0c80bee3431c73f69c F www/nulls.tcl ec35193f92485b87b90a994a01d0171b58823fcf @@ -351,7 +351,7 @@ F www/tclsqlite.tcl bb0d1357328a42b1993d78573e587c6dcbc964b9 F www/vdbe.tcl 87a31ace769f20d3627a64fa1fade7fed47b90d0 F www/version3.tcl a99cf5f6d8bd4d5537584a2b342f0fb9fa601d8b F www/whentouse.tcl 97e2b5cd296f7d8057e11f44427dea8a4c2db513 -P c72b946198128cbceb12dffbdf4706d9fda0fd72 -R be1e635cafb90b5983ca91c9370b824f +P 44bd7ba432123ec77904b862d11521f4ab96d2cf +R dfa46f13c8dc60b1e9e94224c227881b U drh -Z d6f4b8669c07081bb92ea3ba047fbeee +Z 3323dfe512cf86b69d178e38ebdbf07d diff --git a/manifest.uuid b/manifest.uuid index 84493ebc99..85a0986f4d 100644 --- a/manifest.uuid +++ b/manifest.uuid @@ -1 +1 @@ -44bd7ba432123ec77904b862d11521f4ab96d2cf \ No newline at end of file +9e04f8fdf1ec0dc36effb55c05d075b3b4777fef \ No newline at end of file diff --git a/src/func.c b/src/func.c index 3e685c6e44..0e050f80a6 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.120 2006/02/09 18:35:30 drh Exp $ +** $Id: func.c,v 1.121 2006/02/09 22:13:42 drh Exp $ */ #include "sqliteInt.h" #include @@ -819,7 +819,7 @@ typedef struct SumCtx SumCtx; struct SumCtx { LONGDOUBLE_TYPE sum; /* Sum of terms */ i64 cnt; /* Number of elements summed */ - u8 seenFloat; /* True if there has been any floating point value */ + u8 approx; /* True if sum is approximate */ }; /* @@ -830,18 +830,33 @@ struct SumCtx { ** 0.0 in that case. In addition, TOTAL always returns a float where ** SUM might return an integer if it never encounters a floating point ** value. +** +** I am told that SUM() should raise an exception if it encounters +** a integer overflow. But after pondering this, I decided that +** behavior leads to brittle programs. So instead, I have coded +** SUM() to revert to using floating point if it encounters an +** integer overflow. The answer may not be exact, but it will be +** close. If the SUM() function returns an integer, the value is +** exact. If SUM() returns a floating point value, it means the +** value might be approximated. */ static void sumStep(sqlite3_context *context, int argc, sqlite3_value **argv){ SumCtx *p; int type; assert( argc==1 ); p = sqlite3_aggregate_context(context, sizeof(*p)); - type = sqlite3_value_type(argv[0]); + type = sqlite3_value_numeric_type(argv[0]); if( p && type!=SQLITE_NULL ){ - p->sum += sqlite3_value_double(argv[0]); p->cnt++; - if( type==SQLITE_FLOAT ){ - p->seenFloat = 1; + if( type==SQLITE_INTEGER ){ + p->sum += sqlite3_value_int64(argv[0]); + if( !p->approx ){ + i64 iVal; + p->approx = p->sum!=(LONGDOUBLE_TYPE)(iVal = (i64)p->sum); + } + }else{ + p->sum += sqlite3_value_double(argv[0]); + p->approx = 1; } } } @@ -849,13 +864,10 @@ static void sumFinalize(sqlite3_context *context){ SumCtx *p; p = sqlite3_aggregate_context(context, 0); if( p && p->cnt>0 ){ - i64 iVal = (i64)p->sum; - if( p->seenFloat ){ + if( p->approx ){ sqlite3_result_double(context, p->sum); - }else if( p->sum==(LONGDOUBLE_TYPE)iVal ){ - sqlite3_result_int64(context, iVal); }else{ - sqlite3_result_error(context, "integer overflow", -1); + sqlite3_result_int64(context, (i64)p->sum); } } } diff --git a/src/sqlite.h.in b/src/sqlite.h.in index 09803f75ff..79d64f4ff4 100644 --- a/src/sqlite.h.in +++ b/src/sqlite.h.in @@ -12,7 +12,7 @@ ** This header file defines the interface that the SQLite library ** presents to client programs. ** -** @(#) $Id: sqlite.h.in,v 1.159 2006/02/09 18:35:30 drh Exp $ +** @(#) $Id: sqlite.h.in,v 1.160 2006/02/09 22:13:42 drh Exp $ */ #ifndef _SQLITE3_H_ #define _SQLITE3_H_ @@ -898,6 +898,7 @@ sqlite_int64 sqlite3_column_int64(sqlite3_stmt*, int iCol); const unsigned char *sqlite3_column_text(sqlite3_stmt*, int iCol); const void *sqlite3_column_text16(sqlite3_stmt*, int iCol); int sqlite3_column_type(sqlite3_stmt*, int iCol); +int sqlite3_column_numeric_type(sqlite3_stmt*, int iCol); /* ** The sqlite3_finalize() function is called to delete a compiled @@ -1005,6 +1006,7 @@ const void *sqlite3_value_text16(sqlite3_value*); const void *sqlite3_value_text16le(sqlite3_value*); const void *sqlite3_value_text16be(sqlite3_value*); int sqlite3_value_type(sqlite3_value*); +int sqlite3_value_numeric_type(sqlite3_value*); /* ** Aggregate functions use the following routine to allocate diff --git a/src/test_md5.c b/src/test_md5.c index f0da4db5e1..820fb10071 100644 --- a/src/test_md5.c +++ b/src/test_md5.c @@ -353,9 +353,6 @@ int Md5_Init(Tcl_Interp *interp){ return TCL_OK; } -/* -** - /* ** During testing, the special md5sum() aggregate function is available. ** inside SQLite. The following routines implement that function. diff --git a/src/vdbe.c b/src/vdbe.c index 557b9e8b19..f8d5af1630 100644 --- a/src/vdbe.c +++ b/src/vdbe.c @@ -43,7 +43,7 @@ ** in this file for details. If in doubt, do not deviate from existing ** commenting and indentation practices when changing or adding code. ** -** $Id: vdbe.c,v 1.541 2006/01/31 19:31:44 drh Exp $ +** $Id: vdbe.c,v 1.542 2006/02/09 22:13:42 drh Exp $ */ #include "sqliteInt.h" #include "os.h" @@ -189,6 +189,31 @@ static Cursor *allocateCursor(Vdbe *p, int iCur, int iDb){ return pCx; } +/* +** Try to convert a value into a numeric representation if we can +** do so without loss of information. In other words, if the string +** looks like a number, convert it into a number. If it does not +** look like a number, leave it alone. +*/ +static void applyNumericAffinity(Mem *pRec){ + if( (pRec->flags & (MEM_Real|MEM_Int))==0 ){ + int realnum; + sqlite3VdbeMemNulTerminate(pRec); + if( (pRec->flags&MEM_Str) + && sqlite3IsNumber(pRec->z, &realnum, pRec->enc) ){ + i64 value; + sqlite3VdbeChangeEncoding(pRec, SQLITE_UTF8); + if( !realnum && sqlite3atoi64(pRec->z, &value) ){ + sqlite3VdbeMemRelease(pRec); + pRec->i = value; + pRec->flags = MEM_Int; + }else{ + sqlite3VdbeMemRealify(pRec); + } + } + } +} + /* ** Processing is determine by the affinity parameter: ** @@ -220,31 +245,28 @@ static void applyAffinity(Mem *pRec, char affinity, u8 enc){ }else if( affinity!=SQLITE_AFF_NONE ){ assert( affinity==SQLITE_AFF_INTEGER || affinity==SQLITE_AFF_REAL || affinity==SQLITE_AFF_NUMERIC ); - if( 0==(pRec->flags&(MEM_Real|MEM_Int)) ){ - /* pRec does not have a valid integer or real representation. - ** Attempt a conversion if pRec has a string representation and - ** it looks like a number. - */ - int realnum; - sqlite3VdbeMemNulTerminate(pRec); - if( (pRec->flags&MEM_Str) - && sqlite3IsNumber(pRec->z, &realnum, pRec->enc) ){ - i64 value; - sqlite3VdbeChangeEncoding(pRec, SQLITE_UTF8); - if( !realnum && sqlite3atoi64(pRec->z, &value) ){ - sqlite3VdbeMemRelease(pRec); - pRec->i = value; - pRec->flags = MEM_Int; - }else{ - sqlite3VdbeMemNumerify(pRec); - } - } - }else if( pRec->flags & MEM_Real ){ + applyNumericAffinity(pRec); + if( pRec->flags & MEM_Real ){ sqlite3VdbeIntegerAffinity(pRec); } } } +/* +** Try to convert the type of a function argument or a result column +** into a numeric representation. Use either INTEGER or REAL whichever +** is appropriate. But only do the conversion if it is possible without +** loss of information and return the revised type of the argument. +** +** This is an EXPERIMENTAL api and is subject to change or removal. +*/ +int sqlite3_value_numeric_type(sqlite3_value *pVal){ + Mem *pMem = (Mem*)pVal; + applyNumericAffinity(pMem); + storeTypeInfo(pMem, 0); + return pMem->type; +} + /* ** Exported version of applyAffinity(). This one works on sqlite3_value*, ** not the internal Mem* type. diff --git a/src/vdbeapi.c b/src/vdbeapi.c index 9ab0474656..497f6c0095 100644 --- a/src/vdbeapi.c +++ b/src/vdbeapi.c @@ -74,6 +74,7 @@ const void *sqlite3_value_text16le(sqlite3_value *pVal){ int sqlite3_value_type(sqlite3_value* pVal){ return pVal->type; } +/* sqlite3_value_numeric_type() defined in vdbe.c */ /**************************** sqlite3_result_ ******************************* ** The following routines are used by user-defined functions to specify @@ -469,6 +470,13 @@ int sqlite3_column_type(sqlite3_stmt *pStmt, int i){ return sqlite3_value_type( columnMem(pStmt,i) ); } +/* The following function is experimental and subject to change or +** removal */ +/*int sqlite3_column_numeric_type(sqlite3_stmt *pStmt, int i){ +** return sqlite3_value_numeric_type( columnMem(pStmt,i) ); +**} +*/ + /* ** Convert the N-th element of pStmt->pColName[] into a string using ** xFunc() then return that string. If N is out of range, return 0. diff --git a/test/func.test b/test/func.test index d2b274de9d..add3160fe2 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.46 2006/02/09 17:47:42 drh Exp $ +# $Id: func.test,v 1.47 2006/02/09 22:13:42 drh Exp $ set testdir [file dirname $argv0] source $testdir/tester.tcl @@ -551,7 +551,9 @@ do_test func-18.10 { } } 0 -# Ticket #1669: If an integer SUM overflows, throw an error, thus +# Ticket #1669, #1670: I am told that if an integer overflow occurs +# during a sum that the result should be an error. This strikes me +# as being brittle. So I'm not doing it that way. # making the SQL-standard version SUM() even more useless than it # was before. # @@ -563,11 +565,11 @@ do_test func-18.11 { } } integer do_test func-18.12 { - catchsql { + execsql { INSERT INTO t6 VALUES(1<<62); SELECT sum(x) - ((1<<62)*2.0+1) from t6; } -} {1 {integer overflow}} +} {0.0} do_test func-18.13 { execsql { SELECT total(x) - ((1<<62)*2.0+1) FROM t6 diff --git a/test/select1.test b/test/select1.test index 58270c5828..b8aa78fc22 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.47 2006/01/14 08:02:28 danielk1977 Exp $ +# $Id: select1.test,v 1.48 2006/02/09 22:13:42 drh Exp $ set testdir [file dirname $argv0] source $testdir/tester.tcl @@ -211,7 +211,7 @@ do_test select1-2.17 { } {0 45} do_test select1-2.17.1 { execsql {SELECT sum(a) FROM t3} -} {44} +} {44.0} do_test select1-2.18 { set v [catch {execsql {SELECT XYZZY(f1) FROM test1}} msg] lappend v $msg @@ -828,4 +828,3 @@ ifcapable subquery { } finish_test - diff --git a/www/lang.tcl b/www/lang.tcl index 80dd89ab08..4fa79d817a 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.107 2006/01/30 23:04:52 drh Exp $} +set rcsid {$Id: lang.tcl,v 1.108 2006/02/09 22:13:42 drh Exp $} source common.tcl if {[llength $argv]>0} { @@ -1366,7 +1366,10 @@ values in column X. avg(X) Return the average value of all non-NULL X within a -group. Non-numeric values are interpreted as 0. +group. String and BLOB values that do not look like numbers are +interpreted as 0. +The result of avg() is always a floating point value even if all +inputs are integers.

@@ -1391,15 +1394,23 @@ if all values in the group are NULL. sum(X)
total(X) -Return the numeric sum of all numeric values in the group. - If there are no input rows or all values are NULL, then sum() returns - NULL but total() returns zero. - NULL is not a helpful result in that case (the correct answer should be - zero) but the SQL standard requires that behavior from sum() and that is how - most other SQL database engines implement sum() so SQLite does it that way - in order to be compatible. The non-standard total() function is provided - as a convenient way - to work around this design problem in the SQL language. +Return the numeric sum of all non-NULL values in the group. + If there are no non-NULL input rows then sum() returns + NULL but total() returns 0.0. + NULL is not normally a helpful result for the sum of no rows + but the SQL standard requires it and most other + SQL database engines implement sum() that way so SQLite does it in the + same way in order to be compatible. The non-standard total() function + is provided as a convenient way to work around this design problem + in the SQL language.

+ +

The result of total() is always a floating point value. + The result of sum() is an integer value if all non-NULL inputs are integers + and the sum is exact. If any input to sum() is neither an integer or + a NULL or if the + an integer overflow occurs at any point during the computation, + then sum() returns a floating point value + which might be an approximation to the true sum. }