xref: /onnv-gate/usr/src/lib/libsqlite/test/func.test (revision 4520:7dbeadedd7fe)
1*4520Snw141292
2*4520Snw141292#pragma ident	"%Z%%M%	%I%	%E% SMI"
3*4520Snw141292
4*4520Snw141292# 2001 September 15
5*4520Snw141292#
6*4520Snw141292# The author disclaims copyright to this source code.  In place of
7*4520Snw141292# a legal notice, here is a blessing:
8*4520Snw141292#
9*4520Snw141292#    May you do good and not evil.
10*4520Snw141292#    May you find forgiveness for yourself and forgive others.
11*4520Snw141292#    May you share freely, never taking more than you give.
12*4520Snw141292#
13*4520Snw141292#***********************************************************************
14*4520Snw141292# This file implements regression tests for SQLite library.  The
15*4520Snw141292# focus of this file is testing built-in functions.
16*4520Snw141292#
17*4520Snw141292# $Id: func.test,v 1.16.2.2 2004/07/18 21:14:05 drh Exp $
18*4520Snw141292
19*4520Snw141292set testdir [file dirname $argv0]
20*4520Snw141292source $testdir/tester.tcl
21*4520Snw141292
22*4520Snw141292# Create a table to work with.
23*4520Snw141292#
24*4520Snw141292do_test func-0.0 {
25*4520Snw141292  execsql {CREATE TABLE tbl1(t1 text)}
26*4520Snw141292  foreach word {this program is free software} {
27*4520Snw141292    execsql "INSERT INTO tbl1 VALUES('$word')"
28*4520Snw141292  }
29*4520Snw141292  execsql {SELECT t1 FROM tbl1 ORDER BY t1}
30*4520Snw141292} {free is program software this}
31*4520Snw141292do_test func-0.1 {
32*4520Snw141292  execsql {
33*4520Snw141292     CREATE TABLE t2(a);
34*4520Snw141292     INSERT INTO t2 VALUES(1);
35*4520Snw141292     INSERT INTO t2 VALUES(NULL);
36*4520Snw141292     INSERT INTO t2 VALUES(345);
37*4520Snw141292     INSERT INTO t2 VALUES(NULL);
38*4520Snw141292     INSERT INTO t2 VALUES(67890);
39*4520Snw141292     SELECT * FROM t2;
40*4520Snw141292  }
41*4520Snw141292} {1 {} 345 {} 67890}
42*4520Snw141292
43*4520Snw141292# Check out the length() function
44*4520Snw141292#
45*4520Snw141292do_test func-1.0 {
46*4520Snw141292  execsql {SELECT length(t1) FROM tbl1 ORDER BY t1}
47*4520Snw141292} {4 2 7 8 4}
48*4520Snw141292do_test func-1.1 {
49*4520Snw141292  set r [catch {execsql {SELECT length(*) FROM tbl1 ORDER BY t1}} msg]
50*4520Snw141292  lappend r $msg
51*4520Snw141292} {1 {wrong number of arguments to function length()}}
52*4520Snw141292do_test func-1.2 {
53*4520Snw141292  set r [catch {execsql {SELECT length(t1,5) FROM tbl1 ORDER BY t1}} msg]
54*4520Snw141292  lappend r $msg
55*4520Snw141292} {1 {wrong number of arguments to function length()}}
56*4520Snw141292do_test func-1.3 {
57*4520Snw141292  execsql {SELECT length(t1), count(*) FROM tbl1 GROUP BY length(t1)
58*4520Snw141292           ORDER BY length(t1)}
59*4520Snw141292} {2 1 4 2 7 1 8 1}
60*4520Snw141292do_test func-1.4 {
61*4520Snw141292  execsql {SELECT coalesce(length(a),-1) FROM t2}
62*4520Snw141292} {1 -1 3 -1 5}
63*4520Snw141292
64*4520Snw141292# Check out the substr() function
65*4520Snw141292#
66*4520Snw141292do_test func-2.0 {
67*4520Snw141292  execsql {SELECT substr(t1,1,2) FROM tbl1 ORDER BY t1}
68*4520Snw141292} {fr is pr so th}
69*4520Snw141292do_test func-2.1 {
70*4520Snw141292  execsql {SELECT substr(t1,2,1) FROM tbl1 ORDER BY t1}
71*4520Snw141292} {r s r o h}
72*4520Snw141292do_test func-2.2 {
73*4520Snw141292  execsql {SELECT substr(t1,3,3) FROM tbl1 ORDER BY t1}
74*4520Snw141292} {ee {} ogr ftw is}
75*4520Snw141292do_test func-2.3 {
76*4520Snw141292  execsql {SELECT substr(t1,-1,1) FROM tbl1 ORDER BY t1}
77*4520Snw141292} {e s m e s}
78*4520Snw141292do_test func-2.4 {
79*4520Snw141292  execsql {SELECT substr(t1,-1,2) FROM tbl1 ORDER BY t1}
80*4520Snw141292} {e s m e s}
81*4520Snw141292do_test func-2.5 {
82*4520Snw141292  execsql {SELECT substr(t1,-2,1) FROM tbl1 ORDER BY t1}
83*4520Snw141292} {e i a r i}
84*4520Snw141292do_test func-2.6 {
85*4520Snw141292  execsql {SELECT substr(t1,-2,2) FROM tbl1 ORDER BY t1}
86*4520Snw141292} {ee is am re is}
87*4520Snw141292do_test func-2.7 {
88*4520Snw141292  execsql {SELECT substr(t1,-4,2) FROM tbl1 ORDER BY t1}
89*4520Snw141292} {fr {} gr wa th}
90*4520Snw141292do_test func-2.8 {
91*4520Snw141292  execsql {SELECT t1 FROM tbl1 ORDER BY substr(t1,2,20)}
92*4520Snw141292} {this software free program is}
93*4520Snw141292do_test func-2.9 {
94*4520Snw141292  execsql {SELECT substr(a,1,1) FROM t2}
95*4520Snw141292} {1 {} 3 {} 6}
96*4520Snw141292do_test func-2.10 {
97*4520Snw141292  execsql {SELECT substr(a,2,2) FROM t2}
98*4520Snw141292} {{} {} 45 {} 78}
99*4520Snw141292
100*4520Snw141292# Only do the following tests if TCL has UTF-8 capabilities and
101*4520Snw141292# the UTF-8 encoding is turned on in the SQLite library.
102*4520Snw141292#
103*4520Snw141292if {[sqlite -encoding]=="UTF-8" && "\u1234"!="u1234"} {
104*4520Snw141292
105*4520Snw141292# Put some UTF-8 characters in the database
106*4520Snw141292#
107*4520Snw141292do_test func-3.0 {
108*4520Snw141292  execsql {DELETE FROM tbl1}
109*4520Snw141292  foreach word "contains UTF-8 characters hi\u1234ho" {
110*4520Snw141292    execsql "INSERT INTO tbl1 VALUES('$word')"
111*4520Snw141292  }
112*4520Snw141292  execsql {SELECT t1 FROM tbl1 ORDER BY t1}
113*4520Snw141292} "UTF-8 characters contains hi\u1234ho"
114*4520Snw141292do_test func-3.1 {
115*4520Snw141292  execsql {SELECT length(t1) FROM tbl1 ORDER BY t1}
116*4520Snw141292} {5 10 8 5}
117*4520Snw141292do_test func-3.2 {
118*4520Snw141292  execsql {SELECT substr(t1,1,2) FROM tbl1 ORDER BY t1}
119*4520Snw141292} {UT ch co hi}
120*4520Snw141292do_test func-3.3 {
121*4520Snw141292  execsql {SELECT substr(t1,1,3) FROM tbl1 ORDER BY t1}
122*4520Snw141292} "UTF cha con hi\u1234"
123*4520Snw141292do_test func-3.4 {
124*4520Snw141292  execsql {SELECT substr(t1,2,2) FROM tbl1 ORDER BY t1}
125*4520Snw141292} "TF ha on i\u1234"
126*4520Snw141292do_test func-3.5 {
127*4520Snw141292  execsql {SELECT substr(t1,2,3) FROM tbl1 ORDER BY t1}
128*4520Snw141292} "TF- har ont i\u1234h"
129*4520Snw141292do_test func-3.6 {
130*4520Snw141292  execsql {SELECT substr(t1,3,2) FROM tbl1 ORDER BY t1}
131*4520Snw141292} "F- ar nt \u1234h"
132*4520Snw141292do_test func-3.7 {
133*4520Snw141292  execsql {SELECT substr(t1,4,2) FROM tbl1 ORDER BY t1}
134*4520Snw141292} "-8 ra ta ho"
135*4520Snw141292do_test func-3.8 {
136*4520Snw141292  execsql {SELECT substr(t1,-1,1) FROM tbl1 ORDER BY t1}
137*4520Snw141292} "8 s s o"
138*4520Snw141292do_test func-3.9 {
139*4520Snw141292  execsql {SELECT substr(t1,-3,2) FROM tbl1 ORDER BY t1}
140*4520Snw141292} "F- er in \u1234h"
141*4520Snw141292do_test func-3.10 {
142*4520Snw141292  execsql {SELECT substr(t1,-4,3) FROM tbl1 ORDER BY t1}
143*4520Snw141292} "TF- ter ain i\u1234h"
144*4520Snw141292do_test func-3.99 {
145*4520Snw141292  execsql {DELETE FROM tbl1}
146*4520Snw141292  foreach word {this program is free software} {
147*4520Snw141292    execsql "INSERT INTO tbl1 VALUES('$word')"
148*4520Snw141292  }
149*4520Snw141292  execsql {SELECT t1 FROM tbl1}
150*4520Snw141292} {this program is free software}
151*4520Snw141292
152*4520Snw141292} ;# End [sqlite -encoding]==UTF-8 and \u1234!=u1234
153*4520Snw141292
154*4520Snw141292# Test the abs() and round() functions.
155*4520Snw141292#
156*4520Snw141292do_test func-4.1 {
157*4520Snw141292  execsql {
158*4520Snw141292    CREATE TABLE t1(a,b,c);
159*4520Snw141292    INSERT INTO t1 VALUES(1,2,3);
160*4520Snw141292    INSERT INTO t1 VALUES(2,1.2345678901234,-12345.67890);
161*4520Snw141292    INSERT INTO t1 VALUES(3,-2,-5);
162*4520Snw141292  }
163*4520Snw141292  catchsql {SELECT abs(a,b) FROM t1}
164*4520Snw141292} {1 {wrong number of arguments to function abs()}}
165*4520Snw141292do_test func-4.2 {
166*4520Snw141292  catchsql {SELECT abs() FROM t1}
167*4520Snw141292} {1 {wrong number of arguments to function abs()}}
168*4520Snw141292do_test func-4.3 {
169*4520Snw141292  catchsql {SELECT abs(b) FROM t1 ORDER BY a}
170*4520Snw141292} {0 {2 1.2345678901234 2}}
171*4520Snw141292do_test func-4.4 {
172*4520Snw141292  catchsql {SELECT abs(c) FROM t1 ORDER BY a}
173*4520Snw141292} {0 {3 12345.67890 5}}
174*4520Snw141292do_test func-4.4.1 {
175*4520Snw141292  execsql {SELECT abs(a) FROM t2}
176*4520Snw141292} {1 {} 345 {} 67890}
177*4520Snw141292do_test func-4.4.2 {
178*4520Snw141292  execsql {SELECT abs(t1) FROM tbl1}
179*4520Snw141292} {this program is free software}
180*4520Snw141292
181*4520Snw141292do_test func-4.5 {
182*4520Snw141292  catchsql {SELECT round(a,b,c) FROM t1}
183*4520Snw141292} {1 {wrong number of arguments to function round()}}
184*4520Snw141292do_test func-4.6 {
185*4520Snw141292  catchsql {SELECT round(b,2) FROM t1 ORDER BY b}
186*4520Snw141292} {0 {-2.00 1.23 2.00}}
187*4520Snw141292do_test func-4.7 {
188*4520Snw141292  catchsql {SELECT round(b,0) FROM t1 ORDER BY a}
189*4520Snw141292} {0 {2 1 -2}}
190*4520Snw141292do_test func-4.8 {
191*4520Snw141292  catchsql {SELECT round(c) FROM t1 ORDER BY a}
192*4520Snw141292} {0 {3 -12346 -5}}
193*4520Snw141292do_test func-4.9 {
194*4520Snw141292  catchsql {SELECT round(c,a) FROM t1 ORDER BY a}
195*4520Snw141292} {0 {3.0 -12345.68 -5.000}}
196*4520Snw141292do_test func-4.10 {
197*4520Snw141292  catchsql {SELECT 'x' || round(c,a) || 'y' FROM t1 ORDER BY a}
198*4520Snw141292} {0 {x3.0y x-12345.68y x-5.000y}}
199*4520Snw141292do_test func-4.11 {
200*4520Snw141292  catchsql {SELECT round() FROM t1 ORDER BY a}
201*4520Snw141292} {1 {wrong number of arguments to function round()}}
202*4520Snw141292do_test func-4.12 {
203*4520Snw141292  execsql {SELECT coalesce(round(a,2),'nil') FROM t2}
204*4520Snw141292} {1.00 nil 345.00 nil 67890.00}
205*4520Snw141292do_test func-4.13 {
206*4520Snw141292  execsql {SELECT round(t1,2) FROM tbl1}
207*4520Snw141292} {0.00 0.00 0.00 0.00 0.00}
208*4520Snw141292
209*4520Snw141292# Test the upper() and lower() functions
210*4520Snw141292#
211*4520Snw141292do_test func-5.1 {
212*4520Snw141292  execsql {SELECT upper(t1) FROM tbl1}
213*4520Snw141292} {THIS PROGRAM IS FREE SOFTWARE}
214*4520Snw141292do_test func-5.2 {
215*4520Snw141292  execsql {SELECT lower(upper(t1)) FROM tbl1}
216*4520Snw141292} {this program is free software}
217*4520Snw141292do_test func-5.3 {
218*4520Snw141292  execsql {SELECT upper(a), lower(a) FROM t2}
219*4520Snw141292} {1 1 {} {} 345 345 {} {} 67890 67890}
220*4520Snw141292do_test func-5.4 {
221*4520Snw141292  catchsql {SELECT upper(a,5) FROM t2}
222*4520Snw141292} {1 {wrong number of arguments to function upper()}}
223*4520Snw141292do_test func-5.5 {
224*4520Snw141292  catchsql {SELECT upper(*) FROM t2}
225*4520Snw141292} {1 {wrong number of arguments to function upper()}}
226*4520Snw141292
227*4520Snw141292# Test the coalesce() and nullif() functions
228*4520Snw141292#
229*4520Snw141292do_test func-6.1 {
230*4520Snw141292  execsql {SELECT coalesce(a,'xyz') FROM t2}
231*4520Snw141292} {1 xyz 345 xyz 67890}
232*4520Snw141292do_test func-6.2 {
233*4520Snw141292  execsql {SELECT coalesce(upper(a),'nil') FROM t2}
234*4520Snw141292} {1 nil 345 nil 67890}
235*4520Snw141292do_test func-6.3 {
236*4520Snw141292  execsql {SELECT coalesce(nullif(1,1),'nil')}
237*4520Snw141292} {nil}
238*4520Snw141292do_test func-6.4 {
239*4520Snw141292  execsql {SELECT coalesce(nullif(1,2),'nil')}
240*4520Snw141292} {1}
241*4520Snw141292do_test func-6.5 {
242*4520Snw141292  execsql {SELECT coalesce(nullif(1,NULL),'nil')}
243*4520Snw141292} {1}
244*4520Snw141292
245*4520Snw141292
246*4520Snw141292# Test the last_insert_rowid() function
247*4520Snw141292#
248*4520Snw141292do_test func-7.1 {
249*4520Snw141292  execsql {SELECT last_insert_rowid()}
250*4520Snw141292} [db last_insert_rowid]
251*4520Snw141292
252*4520Snw141292# Tests for aggregate functions and how they handle NULLs.
253*4520Snw141292#
254*4520Snw141292do_test func-8.1 {
255*4520Snw141292  execsql {
256*4520Snw141292    SELECT sum(a), count(a), round(avg(a),2), min(a), max(a), count(*) FROM t2;
257*4520Snw141292  }
258*4520Snw141292} {68236 3 22745.33 1 67890 5}
259*4520Snw141292do_test func-8.2 {
260*4520Snw141292  execsql {
261*4520Snw141292    SELECT max('z+'||a||'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOP') FROM t2;
262*4520Snw141292  }
263*4520Snw141292} {z+67890abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOP}
264*4520Snw141292do_test func-8.3 {
265*4520Snw141292  execsql {
266*4520Snw141292    CREATE TEMP TABLE t3 AS SELECT a FROM t2 ORDER BY a DESC;
267*4520Snw141292    SELECT min('z+'||a||'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOP') FROM t3;
268*4520Snw141292  }
269*4520Snw141292} {z+1abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOP}
270*4520Snw141292do_test func-8.4 {
271*4520Snw141292  execsql {
272*4520Snw141292    SELECT max('z+'||a||'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOP') FROM t3;
273*4520Snw141292  }
274*4520Snw141292} {z+67890abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOP}
275*4520Snw141292
276*4520Snw141292# How do you test the random() function in a meaningful, deterministic way?
277*4520Snw141292#
278*4520Snw141292do_test func-9.1 {
279*4520Snw141292  execsql {
280*4520Snw141292    SELECT random() is not null;
281*4520Snw141292  }
282*4520Snw141292} {1}
283*4520Snw141292
284*4520Snw141292# Use the "sqlite_register_test_function" TCL command which is part of
285*4520Snw141292# the text fixture in order to verify correct operation of some of
286*4520Snw141292# the user-defined SQL function APIs that are not used by the built-in
287*4520Snw141292# functions.
288*4520Snw141292#
289*4520Snw141292db close
290*4520Snw141292set ::DB [sqlite db test.db]
291*4520Snw141292sqlite_register_test_function $::DB testfunc
292*4520Snw141292do_test func-10.1 {
293*4520Snw141292  catchsql {
294*4520Snw141292    SELECT testfunc(NULL,NULL);
295*4520Snw141292  }
296*4520Snw141292} {1 {first argument to test function may not be NULL}}
297*4520Snw141292do_test func-10.2 {
298*4520Snw141292  execsql {
299*4520Snw141292    SELECT testfunc(
300*4520Snw141292     'string', 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ',
301*4520Snw141292     'int', 1234
302*4520Snw141292    );
303*4520Snw141292  }
304*4520Snw141292} {1234}
305*4520Snw141292do_test func-10.3 {
306*4520Snw141292  execsql {
307*4520Snw141292    SELECT testfunc(
308*4520Snw141292     'string', 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ',
309*4520Snw141292     'string', NULL
310*4520Snw141292    );
311*4520Snw141292  }
312*4520Snw141292} {{}}
313*4520Snw141292do_test func-10.4 {
314*4520Snw141292  execsql {
315*4520Snw141292    SELECT testfunc(
316*4520Snw141292     'string', 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ',
317*4520Snw141292     'double', 1.234
318*4520Snw141292    );
319*4520Snw141292  }
320*4520Snw141292} {1.234}
321*4520Snw141292do_test func-10.5 {
322*4520Snw141292  execsql {
323*4520Snw141292    SELECT testfunc(
324*4520Snw141292     'string', 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ',
325*4520Snw141292     'int', 1234,
326*4520Snw141292     'string', 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ',
327*4520Snw141292     'string', NULL,
328*4520Snw141292     'string', 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ',
329*4520Snw141292     'double', 1.234,
330*4520Snw141292     'string', 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ',
331*4520Snw141292     'int', 1234,
332*4520Snw141292     'string', 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ',
333*4520Snw141292     'string', NULL,
334*4520Snw141292     'string', 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ',
335*4520Snw141292     'double', 1.234
336*4520Snw141292    );
337*4520Snw141292  }
338*4520Snw141292} {1.234}
339*4520Snw141292
340*4520Snw141292# Test the built-in sqlite_version(*) SQL function.
341*4520Snw141292#
342*4520Snw141292do_test func-11.1 {
343*4520Snw141292  execsql {
344*4520Snw141292    SELECT sqlite_version(*);
345*4520Snw141292  }
346*4520Snw141292} [sqlite -version]
347*4520Snw141292
348*4520Snw141292finish_test
349