blob: 6a87f1283cd577f3c606ab6bb4528858aec2e713 [file] [log] [blame]
drhb19a2bc2001-09-16 00:13:26 +00001# 2001 September 15
drhff6e9112000-08-28 16:21:58 +00002#
drhb19a2bc2001-09-16 00:13:26 +00003# The author disclaims copyright to this source code. In place of
4# a legal notice, here is a blessing:
drhff6e9112000-08-28 16:21:58 +00005#
drhb19a2bc2001-09-16 00:13:26 +00006# May you do good and not evil.
7# May you find forgiveness for yourself and forgive others.
8# May you share freely, never taking more than you give.
drhff6e9112000-08-28 16:21:58 +00009#
10#***********************************************************************
11# This file implements regression tests for SQLite library. The
12# focus of this file is testing built-in functions.
13#
drh7f375902006-06-13 17:38:59 +000014# $Id: func.test,v 1.52 2006/06/13 17:39:01 drh Exp $
drhff6e9112000-08-28 16:21:58 +000015
16set testdir [file dirname $argv0]
17source $testdir/tester.tcl
18
19# Create a table to work with.
20#
drhff6e9112000-08-28 16:21:58 +000021do_test func-0.0 {
drh297ecf12001-04-05 15:57:13 +000022 execsql {CREATE TABLE tbl1(t1 text)}
23 foreach word {this program is free software} {
24 execsql "INSERT INTO tbl1 VALUES('$word')"
25 }
drhff6e9112000-08-28 16:21:58 +000026 execsql {SELECT t1 FROM tbl1 ORDER BY t1}
27} {free is program software this}
drh832508b2002-03-02 17:04:07 +000028do_test func-0.1 {
29 execsql {
30 CREATE TABLE t2(a);
31 INSERT INTO t2 VALUES(1);
32 INSERT INTO t2 VALUES(NULL);
33 INSERT INTO t2 VALUES(345);
34 INSERT INTO t2 VALUES(NULL);
35 INSERT INTO t2 VALUES(67890);
36 SELECT * FROM t2;
37 }
38} {1 {} 345 {} 67890}
drhff6e9112000-08-28 16:21:58 +000039
40# Check out the length() function
41#
42do_test func-1.0 {
43 execsql {SELECT length(t1) FROM tbl1 ORDER BY t1}
44} {4 2 7 8 4}
45do_test func-1.1 {
46 set r [catch {execsql {SELECT length(*) FROM tbl1 ORDER BY t1}} msg]
47 lappend r $msg
drh89425d52002-02-28 03:04:48 +000048} {1 {wrong number of arguments to function length()}}
drhff6e9112000-08-28 16:21:58 +000049do_test func-1.2 {
50 set r [catch {execsql {SELECT length(t1,5) FROM tbl1 ORDER BY t1}} msg]
51 lappend r $msg
drh89425d52002-02-28 03:04:48 +000052} {1 {wrong number of arguments to function length()}}
drhff6e9112000-08-28 16:21:58 +000053do_test func-1.3 {
54 execsql {SELECT length(t1), count(*) FROM tbl1 GROUP BY length(t1)
55 ORDER BY length(t1)}
56} {2 1 4 2 7 1 8 1}
drh832508b2002-03-02 17:04:07 +000057do_test func-1.4 {
drhbb113512002-05-27 01:04:51 +000058 execsql {SELECT coalesce(length(a),-1) FROM t2}
59} {1 -1 3 -1 5}
drhff6e9112000-08-28 16:21:58 +000060
61# Check out the substr() function
62#
63do_test func-2.0 {
64 execsql {SELECT substr(t1,1,2) FROM tbl1 ORDER BY t1}
65} {fr is pr so th}
66do_test func-2.1 {
67 execsql {SELECT substr(t1,2,1) FROM tbl1 ORDER BY t1}
68} {r s r o h}
69do_test func-2.2 {
70 execsql {SELECT substr(t1,3,3) FROM tbl1 ORDER BY t1}
71} {ee {} ogr ftw is}
72do_test func-2.3 {
73 execsql {SELECT substr(t1,-1,1) FROM tbl1 ORDER BY t1}
74} {e s m e s}
75do_test func-2.4 {
76 execsql {SELECT substr(t1,-1,2) FROM tbl1 ORDER BY t1}
77} {e s m e s}
78do_test func-2.5 {
79 execsql {SELECT substr(t1,-2,1) FROM tbl1 ORDER BY t1}
80} {e i a r i}
81do_test func-2.6 {
82 execsql {SELECT substr(t1,-2,2) FROM tbl1 ORDER BY t1}
83} {ee is am re is}
84do_test func-2.7 {
85 execsql {SELECT substr(t1,-4,2) FROM tbl1 ORDER BY t1}
86} {fr {} gr wa th}
87do_test func-2.8 {
88 execsql {SELECT t1 FROM tbl1 ORDER BY substr(t1,2,20)}
89} {this software free program is}
drh832508b2002-03-02 17:04:07 +000090do_test func-2.9 {
91 execsql {SELECT substr(a,1,1) FROM t2}
92} {1 {} 3 {} 6}
93do_test func-2.10 {
94 execsql {SELECT substr(a,2,2) FROM t2}
95} {{} {} 45 {} 78}
drhff6e9112000-08-28 16:21:58 +000096
drhdf014892004-06-02 00:41:09 +000097# Only do the following tests if TCL has UTF-8 capabilities
drh297ecf12001-04-05 15:57:13 +000098#
drhdf014892004-06-02 00:41:09 +000099if {"\u1234"!="u1234"} {
drh297ecf12001-04-05 15:57:13 +0000100
101# Put some UTF-8 characters in the database
102#
103do_test func-3.0 {
104 execsql {DELETE FROM tbl1}
105 foreach word "contains UTF-8 characters hi\u1234ho" {
106 execsql "INSERT INTO tbl1 VALUES('$word')"
107 }
108 execsql {SELECT t1 FROM tbl1 ORDER BY t1}
drha9e99ae2002-08-13 23:02:57 +0000109} "UTF-8 characters contains hi\u1234ho"
drh297ecf12001-04-05 15:57:13 +0000110do_test func-3.1 {
111 execsql {SELECT length(t1) FROM tbl1 ORDER BY t1}
drha9e99ae2002-08-13 23:02:57 +0000112} {5 10 8 5}
drh297ecf12001-04-05 15:57:13 +0000113do_test func-3.2 {
114 execsql {SELECT substr(t1,1,2) FROM tbl1 ORDER BY t1}
drha9e99ae2002-08-13 23:02:57 +0000115} {UT ch co hi}
drh297ecf12001-04-05 15:57:13 +0000116do_test func-3.3 {
117 execsql {SELECT substr(t1,1,3) FROM tbl1 ORDER BY t1}
drha9e99ae2002-08-13 23:02:57 +0000118} "UTF cha con hi\u1234"
drh297ecf12001-04-05 15:57:13 +0000119do_test func-3.4 {
120 execsql {SELECT substr(t1,2,2) FROM tbl1 ORDER BY t1}
drha9e99ae2002-08-13 23:02:57 +0000121} "TF ha on i\u1234"
drh297ecf12001-04-05 15:57:13 +0000122do_test func-3.5 {
123 execsql {SELECT substr(t1,2,3) FROM tbl1 ORDER BY t1}
drha9e99ae2002-08-13 23:02:57 +0000124} "TF- har ont i\u1234h"
drh297ecf12001-04-05 15:57:13 +0000125do_test func-3.6 {
126 execsql {SELECT substr(t1,3,2) FROM tbl1 ORDER BY t1}
drha9e99ae2002-08-13 23:02:57 +0000127} "F- ar nt \u1234h"
drh297ecf12001-04-05 15:57:13 +0000128do_test func-3.7 {
129 execsql {SELECT substr(t1,4,2) FROM tbl1 ORDER BY t1}
drha9e99ae2002-08-13 23:02:57 +0000130} "-8 ra ta ho"
drh297ecf12001-04-05 15:57:13 +0000131do_test func-3.8 {
132 execsql {SELECT substr(t1,-1,1) FROM tbl1 ORDER BY t1}
drha9e99ae2002-08-13 23:02:57 +0000133} "8 s s o"
drh297ecf12001-04-05 15:57:13 +0000134do_test func-3.9 {
135 execsql {SELECT substr(t1,-3,2) FROM tbl1 ORDER BY t1}
drha9e99ae2002-08-13 23:02:57 +0000136} "F- er in \u1234h"
drh297ecf12001-04-05 15:57:13 +0000137do_test func-3.10 {
138 execsql {SELECT substr(t1,-4,3) FROM tbl1 ORDER BY t1}
drha9e99ae2002-08-13 23:02:57 +0000139} "TF- ter ain i\u1234h"
drh832508b2002-03-02 17:04:07 +0000140do_test func-3.99 {
141 execsql {DELETE FROM tbl1}
142 foreach word {this program is free software} {
143 execsql "INSERT INTO tbl1 VALUES('$word')"
144 }
145 execsql {SELECT t1 FROM tbl1}
146} {this program is free software}
drh297ecf12001-04-05 15:57:13 +0000147
drhdf014892004-06-02 00:41:09 +0000148} ;# End \u1234!=u1234
drh297ecf12001-04-05 15:57:13 +0000149
drhbf4133c2001-10-13 02:59:08 +0000150# Test the abs() and round() functions.
151#
152do_test func-4.1 {
153 execsql {
154 CREATE TABLE t1(a,b,c);
155 INSERT INTO t1 VALUES(1,2,3);
156 INSERT INTO t1 VALUES(2,1.2345678901234,-12345.67890);
157 INSERT INTO t1 VALUES(3,-2,-5);
158 }
159 catchsql {SELECT abs(a,b) FROM t1}
drh89425d52002-02-28 03:04:48 +0000160} {1 {wrong number of arguments to function abs()}}
drhbf4133c2001-10-13 02:59:08 +0000161do_test func-4.2 {
162 catchsql {SELECT abs() FROM t1}
drh89425d52002-02-28 03:04:48 +0000163} {1 {wrong number of arguments to function abs()}}
drhbf4133c2001-10-13 02:59:08 +0000164do_test func-4.3 {
165 catchsql {SELECT abs(b) FROM t1 ORDER BY a}
166} {0 {2 1.2345678901234 2}}
167do_test func-4.4 {
168 catchsql {SELECT abs(c) FROM t1 ORDER BY a}
danielk19773d1bfea2004-05-14 11:00:53 +0000169} {0 {3 12345.6789 5}}
drh832508b2002-03-02 17:04:07 +0000170do_test func-4.4.1 {
171 execsql {SELECT abs(a) FROM t2}
172} {1 {} 345 {} 67890}
173do_test func-4.4.2 {
174 execsql {SELECT abs(t1) FROM tbl1}
drh92febd92004-08-20 18:34:20 +0000175} {0.0 0.0 0.0 0.0 0.0}
drhbf4133c2001-10-13 02:59:08 +0000176
177do_test func-4.5 {
178 catchsql {SELECT round(a,b,c) FROM t1}
drh89425d52002-02-28 03:04:48 +0000179} {1 {wrong number of arguments to function round()}}
drhbf4133c2001-10-13 02:59:08 +0000180do_test func-4.6 {
drh8aff1012001-12-22 14:49:24 +0000181 catchsql {SELECT round(b,2) FROM t1 ORDER BY b}
drhd589a922006-03-02 03:02:48 +0000182} {0 {-2.0 1.23 2.0}}
drhbf4133c2001-10-13 02:59:08 +0000183do_test func-4.7 {
184 catchsql {SELECT round(b,0) FROM t1 ORDER BY a}
drhd589a922006-03-02 03:02:48 +0000185} {0 {2.0 1.0 -2.0}}
drhbf4133c2001-10-13 02:59:08 +0000186do_test func-4.8 {
187 catchsql {SELECT round(c) FROM t1 ORDER BY a}
drhd589a922006-03-02 03:02:48 +0000188} {0 {3.0 -12346.0 -5.0}}
drhbf4133c2001-10-13 02:59:08 +0000189do_test func-4.9 {
190 catchsql {SELECT round(c,a) FROM t1 ORDER BY a}
drhd589a922006-03-02 03:02:48 +0000191} {0 {3.0 -12345.68 -5.0}}
drhbf4133c2001-10-13 02:59:08 +0000192do_test func-4.10 {
drh01a34662001-10-20 12:30:10 +0000193 catchsql {SELECT 'x' || round(c,a) || 'y' FROM t1 ORDER BY a}
drhd589a922006-03-02 03:02:48 +0000194} {0 {x3.0y x-12345.68y x-5.0y}}
drh01a34662001-10-20 12:30:10 +0000195do_test func-4.11 {
drhbf4133c2001-10-13 02:59:08 +0000196 catchsql {SELECT round() FROM t1 ORDER BY a}
drh89425d52002-02-28 03:04:48 +0000197} {1 {wrong number of arguments to function round()}}
drh832508b2002-03-02 17:04:07 +0000198do_test func-4.12 {
drhbb113512002-05-27 01:04:51 +0000199 execsql {SELECT coalesce(round(a,2),'nil') FROM t2}
drhd589a922006-03-02 03:02:48 +0000200} {1.0 nil 345.0 nil 67890.0}
drh832508b2002-03-02 17:04:07 +0000201do_test func-4.13 {
202 execsql {SELECT round(t1,2) FROM tbl1}
drhd589a922006-03-02 03:02:48 +0000203} {0.0 0.0 0.0 0.0 0.0}
204do_test func-4.14 {
205 execsql {SELECT typeof(round(5.1,1));}
206} {real}
207do_test func-4.15 {
208 execsql {SELECT typeof(round(5.1));}
209} {real}
210
drh832508b2002-03-02 17:04:07 +0000211
212# Test the upper() and lower() functions
213#
214do_test func-5.1 {
215 execsql {SELECT upper(t1) FROM tbl1}
216} {THIS PROGRAM IS FREE SOFTWARE}
217do_test func-5.2 {
218 execsql {SELECT lower(upper(t1)) FROM tbl1}
219} {this program is free software}
220do_test func-5.3 {
221 execsql {SELECT upper(a), lower(a) FROM t2}
222} {1 1 {} {} 345 345 {} {} 67890 67890}
223do_test func-5.4 {
224 catchsql {SELECT upper(a,5) FROM t2}
225} {1 {wrong number of arguments to function upper()}}
226do_test func-5.5 {
227 catchsql {SELECT upper(*) FROM t2}
228} {1 {wrong number of arguments to function upper()}}
229
drha9f9d1c2002-06-29 02:20:08 +0000230# Test the coalesce() and nullif() functions
drh832508b2002-03-02 17:04:07 +0000231#
232do_test func-6.1 {
233 execsql {SELECT coalesce(a,'xyz') FROM t2}
234} {1 xyz 345 xyz 67890}
235do_test func-6.2 {
236 execsql {SELECT coalesce(upper(a),'nil') FROM t2}
237} {1 nil 345 nil 67890}
drha9f9d1c2002-06-29 02:20:08 +0000238do_test func-6.3 {
239 execsql {SELECT coalesce(nullif(1,1),'nil')}
240} {nil}
241do_test func-6.4 {
242 execsql {SELECT coalesce(nullif(1,2),'nil')}
243} {1}
244do_test func-6.5 {
245 execsql {SELECT coalesce(nullif(1,NULL),'nil')}
246} {1}
247
drh832508b2002-03-02 17:04:07 +0000248
drh6ed41ad2002-04-06 14:10:47 +0000249# Test the last_insert_rowid() function
250#
251do_test func-7.1 {
252 execsql {SELECT last_insert_rowid()}
253} [db last_insert_rowid]
254
drh739105c2002-05-29 23:22:23 +0000255# Tests for aggregate functions and how they handle NULLs.
256#
257do_test func-8.1 {
danielk19774489f9b2005-01-20 02:17:01 +0000258 ifcapable explain {
259 execsql {EXPLAIN SELECT sum(a) FROM t2;}
260 }
drh739105c2002-05-29 23:22:23 +0000261 execsql {
262 SELECT sum(a), count(a), round(avg(a),2), min(a), max(a), count(*) FROM t2;
263 }
drh3d1d95e2005-09-08 10:37:01 +0000264} {68236 3 22745.33 1 67890 5}
drha9f9d1c2002-06-29 02:20:08 +0000265do_test func-8.2 {
266 execsql {
267 SELECT max('z+'||a||'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOP') FROM t2;
268 }
269} {z+67890abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOP}
danielk197753c0f742005-03-29 03:10:59 +0000270
271ifcapable tempdb {
272 do_test func-8.3 {
273 execsql {
274 CREATE TEMP TABLE t3 AS SELECT a FROM t2 ORDER BY a DESC;
275 SELECT min('z+'||a||'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOP') FROM t3;
276 }
277 } {z+1abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOP}
278} else {
279 do_test func-8.3 {
280 execsql {
281 CREATE TABLE t3 AS SELECT a FROM t2 ORDER BY a DESC;
282 SELECT min('z+'||a||'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOP') FROM t3;
283 }
284 } {z+1abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOP}
285}
danielk19773aeab9e2004-06-24 00:20:04 +0000286do_test func-8.4 {
287 execsql {
288 SELECT max('z+'||a||'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOP') FROM t3;
289 }
290} {z+67890abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOP}
drh739105c2002-05-29 23:22:23 +0000291
drha9f9d1c2002-06-29 02:20:08 +0000292# How do you test the random() function in a meaningful, deterministic way?
293#
294do_test func-9.1 {
295 execsql {
296 SELECT random() is not null;
297 }
298} {1}
drhbf4133c2001-10-13 02:59:08 +0000299
drh6cbe1f12002-07-01 00:31:36 +0000300# Use the "sqlite_register_test_function" TCL command which is part of
301# the text fixture in order to verify correct operation of some of
302# the user-defined SQL function APIs that are not used by the built-in
303# functions.
304#
drhdddca282006-01-03 00:33:50 +0000305set ::DB [sqlite3_connection_pointer db]
drh6cbe1f12002-07-01 00:31:36 +0000306sqlite_register_test_function $::DB testfunc
307do_test func-10.1 {
308 catchsql {
309 SELECT testfunc(NULL,NULL);
310 }
danielk19776d88bad2004-05-27 14:23:36 +0000311} {1 {first argument should be one of: int int64 string double null value}}
drh6cbe1f12002-07-01 00:31:36 +0000312do_test func-10.2 {
313 execsql {
314 SELECT testfunc(
315 'string', 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ',
316 'int', 1234
317 );
318 }
319} {1234}
320do_test func-10.3 {
321 execsql {
322 SELECT testfunc(
323 'string', 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ',
324 'string', NULL
325 );
326 }
327} {{}}
328do_test func-10.4 {
329 execsql {
330 SELECT testfunc(
331 'string', 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ',
332 'double', 1.234
333 );
334 }
335} {1.234}
336do_test func-10.5 {
337 execsql {
338 SELECT testfunc(
339 'string', 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ',
340 'int', 1234,
341 'string', 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ',
342 'string', NULL,
343 'string', 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ',
344 'double', 1.234,
345 'string', 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ',
346 'int', 1234,
347 'string', 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ',
348 'string', NULL,
349 'string', 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ',
350 'double', 1.234
351 );
352 }
353} {1.234}
354
drh647cb0e2002-11-04 19:32:25 +0000355# Test the built-in sqlite_version(*) SQL function.
356#
357do_test func-11.1 {
358 execsql {
359 SELECT sqlite_version(*);
360 }
drhef4ac8f2004-06-19 00:16:31 +0000361} [sqlite3 -version]
drh647cb0e2002-11-04 19:32:25 +0000362
drhef4ac8f2004-06-19 00:16:31 +0000363# Test that destructors passed to sqlite3 by calls to sqlite3_result_text()
danielk19773f6b0872004-06-17 05:36:44 +0000364# etc. are called. These tests use two special user-defined functions
365# (implemented in func.c) only available in test builds.
366#
367# Function test_destructor() takes one argument and returns a copy of the
368# text form of that argument. A destructor is associated with the return
369# value. Function test_destructor_count() returns the number of outstanding
370# destructor calls for values returned by test_destructor().
371#
danielk1977d8123362004-06-12 09:25:12 +0000372do_test func-12.1 {
373 execsql {
374 SELECT test_destructor('hello world'), test_destructor_count();
375 }
376} {{hello world} 1}
377do_test func-12.2 {
378 execsql {
379 SELECT test_destructor_count();
380 }
381} {0}
382do_test func-12.3 {
383 execsql {
384 SELECT test_destructor('hello')||' world', test_destructor_count();
385 }
386} {{hello world} 0}
387do_test func-12.4 {
388 execsql {
389 SELECT test_destructor_count();
390 }
391} {0}
392do_test func-12.5 {
393 execsql {
394 CREATE TABLE t4(x);
395 INSERT INTO t4 VALUES(test_destructor('hello'));
396 INSERT INTO t4 VALUES(test_destructor('world'));
397 SELECT min(test_destructor(x)), max(test_destructor(x)) FROM t4;
398 }
399} {hello world}
400do_test func-12.6 {
401 execsql {
402 SELECT test_destructor_count();
403 }
404} {0}
danielk19773f6b0872004-06-17 05:36:44 +0000405do_test func-12.7 {
406 execsql {
407 DROP TABLE t4;
408 }
409} {}
410
411# Test that the auxdata API for scalar functions works. This test uses
412# a special user-defined function only available in test builds,
413# test_auxdata(). Function test_auxdata() takes any number of arguments.
drh92378252006-03-26 01:21:22 +0000414btree_breakpoint
danielk19773f6b0872004-06-17 05:36:44 +0000415do_test func-13.1 {
416 execsql {
417 SELECT test_auxdata('hello world');
418 }
419} {0}
danielk1977ece80f12004-06-23 01:05:26 +0000420
danielk19773f6b0872004-06-17 05:36:44 +0000421do_test func-13.2 {
422 execsql {
423 CREATE TABLE t4(a, b);
424 INSERT INTO t4 VALUES('abc', 'def');
425 INSERT INTO t4 VALUES('ghi', 'jkl');
426 }
427} {}
428do_test func-13.3 {
429 execsql {
430 SELECT test_auxdata('hello world') FROM t4;
431 }
432} {0 1}
433do_test func-13.4 {
434 execsql {
435 SELECT test_auxdata('hello world', 123) FROM t4;
436 }
437} {{0 0} {1 1}}
438do_test func-13.5 {
439 execsql {
440 SELECT test_auxdata('hello world', a) FROM t4;
441 }
442} {{0 0} {1 0}}
443do_test func-13.6 {
444 execsql {
445 SELECT test_auxdata('hello'||'world', a) FROM t4;
446 }
447} {{0 0} {1 0}}
448
449# Test that auxilary data is preserved between calls for SQL variables.
450do_test func-13.7 {
drhdddca282006-01-03 00:33:50 +0000451 set DB [sqlite3_connection_pointer db]
danielk19773f6b0872004-06-17 05:36:44 +0000452 set sql "SELECT test_auxdata( ? , a ) FROM t4;"
453 set STMT [sqlite3_prepare $DB $sql -1 TAIL]
454 sqlite3_bind_text $STMT 1 hello -1
455 set res [list]
456 while { "SQLITE_ROW"==[sqlite3_step $STMT] } {
457 lappend res [sqlite3_column_text $STMT 0]
458 }
459 lappend res [sqlite3_finalize $STMT]
460} {{0 0} {1 0} SQLITE_OK}
danielk1977d8123362004-06-12 09:25:12 +0000461
danielk1977312d6b32004-06-29 13:18:23 +0000462# Make sure that a function with a very long name is rejected
463do_test func-14.1 {
464 catch {
465 db function [string repeat X 254] {return "hello"}
466 }
467} {0}
468do_test func-14.2 {
469 catch {
470 db function [string repeat X 256] {return "hello"}
471 }
472} {1}
473
danielk197701427a62005-01-11 13:02:33 +0000474do_test func-15.1 {
475 catchsql {
476 select test_error(NULL);
477 }
drh90669c12006-01-20 15:45:36 +0000478} {1 {}}
danielk197701427a62005-01-11 13:02:33 +0000479
danielk1977576ec6b2005-01-21 11:55:25 +0000480# Test the quote function for BLOB and NULL values.
481do_test func-16.1 {
482 execsql {
483 CREATE TABLE tbl2(a, b);
484 }
485 set STMT [sqlite3_prepare $::DB "INSERT INTO tbl2 VALUES(?, ?)" -1 TAIL]
486 sqlite3_bind_blob $::STMT 1 abc 3
487 sqlite3_step $::STMT
488 sqlite3_finalize $::STMT
489 execsql {
490 SELECT quote(a), quote(b) FROM tbl2;
491 }
492} {X'616263' NULL}
493
drh2501eb12005-08-12 23:20:53 +0000494# Correctly handle function error messages that include %. Ticket #1354
495#
496do_test func-17.1 {
497 proc testfunc1 args {error "Error %d with %s percents %p"}
498 db function testfunc1 ::testfunc1
499 catchsql {
500 SELECT testfunc1(1,2,3);
501 }
502} {1 {Error %d with %s percents %p}}
503
drh3d1d95e2005-09-08 10:37:01 +0000504# The SUM function should return integer results when all inputs are integer.
505#
506do_test func-18.1 {
507 execsql {
508 CREATE TABLE t5(x);
509 INSERT INTO t5 VALUES(1);
510 INSERT INTO t5 VALUES(-99);
511 INSERT INTO t5 VALUES(10000);
512 SELECT sum(x) FROM t5;
513 }
514} {9902}
515do_test func-18.2 {
516 execsql {
517 INSERT INTO t5 VALUES(0.0);
518 SELECT sum(x) FROM t5;
519 }
drh8a512562005-11-14 22:29:05 +0000520} {9902.0}
danielk1977576ec6b2005-01-21 11:55:25 +0000521
drhc2bd9132005-09-08 20:37:43 +0000522# The sum of nothing is NULL. But the sum of all NULLs is NULL.
drh3f219f42005-09-08 19:45:57 +0000523#
drh76c730c2006-02-09 17:47:42 +0000524# The TOTAL of nothing is 0.0.
525#
drh3f219f42005-09-08 19:45:57 +0000526do_test func-18.3 {
527 execsql {
528 DELETE FROM t5;
drh76c730c2006-02-09 17:47:42 +0000529 SELECT sum(x), total(x) FROM t5;
drh3f219f42005-09-08 19:45:57 +0000530 }
drh76c730c2006-02-09 17:47:42 +0000531} {{} 0.0}
drh3f219f42005-09-08 19:45:57 +0000532do_test func-18.4 {
533 execsql {
534 INSERT INTO t5 VALUES(NULL);
drh76c730c2006-02-09 17:47:42 +0000535 SELECT sum(x), total(x) FROM t5
drh3f219f42005-09-08 19:45:57 +0000536 }
drh76c730c2006-02-09 17:47:42 +0000537} {{} 0.0}
drh3f219f42005-09-08 19:45:57 +0000538do_test func-18.5 {
539 execsql {
540 INSERT INTO t5 VALUES(NULL);
drh76c730c2006-02-09 17:47:42 +0000541 SELECT sum(x), total(x) FROM t5
drh3f219f42005-09-08 19:45:57 +0000542 }
drh76c730c2006-02-09 17:47:42 +0000543} {{} 0.0}
drh3f219f42005-09-08 19:45:57 +0000544do_test func-18.6 {
545 execsql {
546 INSERT INTO t5 VALUES(123);
drh76c730c2006-02-09 17:47:42 +0000547 SELECT sum(x), total(x) FROM t5
drh3f219f42005-09-08 19:45:57 +0000548 }
drh76c730c2006-02-09 17:47:42 +0000549} {123 123.0}
drh5708d2d2005-06-22 10:53:59 +0000550
drh8c08e862006-02-11 17:34:00 +0000551# Ticket #1664, #1669, #1670, #1674: An integer overflow on SUM causes
552# an error. The non-standard TOTAL() function continues to give a helpful
553# result.
drhfc6ad392006-02-09 13:38:19 +0000554#
555do_test func-18.10 {
556 execsql {
557 CREATE TABLE t6(x INTEGER);
558 INSERT INTO t6 VALUES(1);
559 INSERT INTO t6 VALUES(1<<62);
560 SELECT sum(x) - ((1<<62)+1) from t6;
561 }
562} 0
drh76c730c2006-02-09 17:47:42 +0000563do_test func-18.11 {
564 execsql {
565 SELECT typeof(sum(x)) FROM t6
566 }
567} integer
568do_test func-18.12 {
drh8c08e862006-02-11 17:34:00 +0000569 catchsql {
drh76c730c2006-02-09 17:47:42 +0000570 INSERT INTO t6 VALUES(1<<62);
571 SELECT sum(x) - ((1<<62)*2.0+1) from t6;
572 }
drh8c08e862006-02-11 17:34:00 +0000573} {1 {integer overflow}}
drh76c730c2006-02-09 17:47:42 +0000574do_test func-18.13 {
575 execsql {
576 SELECT total(x) - ((1<<62)*2.0+1) FROM t6
577 }
578} 0.0
drh8c08e862006-02-11 17:34:00 +0000579do_test func-18.14 {
580 execsql {
581 SELECT sum(-9223372036854775805);
582 }
583} -9223372036854775805
584do_test func-18.15 {
585 catchsql {
586 SELECT sum(x) FROM
587 (SELECT 9223372036854775807 AS x UNION ALL
588 SELECT 10 AS x);
589 }
590} {1 {integer overflow}}
591do_test func-18.16 {
592 catchsql {
593 SELECT sum(x) FROM
594 (SELECT 9223372036854775807 AS x UNION ALL
595 SELECT -10 AS x);
596 }
597} {0 9223372036854775797}
598do_test func-18.17 {
599 catchsql {
600 SELECT sum(x) FROM
601 (SELECT -9223372036854775807 AS x UNION ALL
602 SELECT 10 AS x);
603 }
604} {0 -9223372036854775797}
605do_test func-18.18 {
606 catchsql {
607 SELECT sum(x) FROM
608 (SELECT -9223372036854775807 AS x UNION ALL
609 SELECT -10 AS x);
610 }
611} {1 {integer overflow}}
612do_test func-18.19 {
613 catchsql {
614 SELECT sum(x) FROM (SELECT 9 AS x UNION ALL SELECT -10 AS x);
615 }
616} {0 -1}
617do_test func-18.20 {
618 catchsql {
619 SELECT sum(x) FROM (SELECT -9 AS x UNION ALL SELECT 10 AS x);
620 }
621} {0 1}
622do_test func-18.21 {
623 catchsql {
624 SELECT sum(x) FROM (SELECT -10 AS x UNION ALL SELECT 9 AS x);
625 }
626} {0 -1}
627do_test func-18.22 {
628 catchsql {
629 SELECT sum(x) FROM (SELECT 10 AS x UNION ALL SELECT -9 AS x);
630 }
631} {0 1}
drh76c730c2006-02-09 17:47:42 +0000632
drh52fc8492006-02-23 21:43:55 +0000633# Integer overflow on abs()
634#
635do_test func-18.31 {
636 catchsql {
637 SELECT abs(-9223372036854775807);
638 }
639} {0 9223372036854775807}
640do_test func-18.32 {
641 catchsql {
642 SELECT abs(-9223372036854775807-1);
643 }
644} {1 {integer overflow}}
645
drh7f375902006-06-13 17:38:59 +0000646# The MATCH function exists but is only a stub and always throws an error.
647#
648do_test func-19.1 {
649 execsql {
650 SELECT match(a,b) FROM t1 WHERE 0;
651 }
652} {}
653do_test func-19.2 {
654 catchsql {
655 SELECT 'abc' MATCH 'xyz';
656 }
657} {1 {MATCH is not implemented}}
658do_test func-19.3 {
659 catchsql {
660 SELECT 'abc' NOT MATCH 'xyz';
661 }
662} {1 {MATCH is not implemented}}
663do_test func-19.4 {
664 catchsql {
665 SELECT match(1,2,3);
666 }
667} {1 {wrong number of arguments to function match()}}
drh76c730c2006-02-09 17:47:42 +0000668
drh5708d2d2005-06-22 10:53:59 +0000669finish_test