1# 2001 September 15 2# 3# The author disclaims copyright to this source code. In place of 4# a legal notice, here is a blessing: 5# 6# 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. 9# 10#*********************************************************************** 11# This file implements regression tests for SQLite library. The 12# focus of this file is testing built-in functions. 13# 14# $Id: func.test,v 1.67 2007/05/15 18:35:21 drh Exp $ 15 16set testdir [file dirname $argv0] 17source $testdir/tester.tcl 18 19# Create a table to work with. 20# 21do_test func-0.0 { 22 execsql {CREATE TABLE tbl1(t1 text)} 23 foreach word {this program is free software} { 24 execsql "INSERT INTO tbl1 VALUES('$word')" 25 } 26 execsql {SELECT t1 FROM tbl1 ORDER BY t1} 27} {free is program software this} 28do_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} 39 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 48} {1 {wrong number of arguments to function length()}} 49do_test func-1.2 { 50 set r [catch {execsql {SELECT length(t1,5) FROM tbl1 ORDER BY t1}} msg] 51 lappend r $msg 52} {1 {wrong number of arguments to function length()}} 53do_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} 57do_test func-1.4 { 58 execsql {SELECT coalesce(length(a),-1) FROM t2} 59} {1 -1 3 -1 5} 60 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} 90do_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} 96 97# Only do the following tests if TCL has UTF-8 capabilities 98# 99if {"\u1234"!="u1234"} { 100 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} 109} "UTF-8 characters contains hi\u1234ho" 110do_test func-3.1 { 111 execsql {SELECT length(t1) FROM tbl1 ORDER BY t1} 112} {5 10 8 5} 113do_test func-3.2 { 114 execsql {SELECT substr(t1,1,2) FROM tbl1 ORDER BY t1} 115} {UT ch co hi} 116do_test func-3.3 { 117 execsql {SELECT substr(t1,1,3) FROM tbl1 ORDER BY t1} 118} "UTF cha con hi\u1234" 119do_test func-3.4 { 120 execsql {SELECT substr(t1,2,2) FROM tbl1 ORDER BY t1} 121} "TF ha on i\u1234" 122do_test func-3.5 { 123 execsql {SELECT substr(t1,2,3) FROM tbl1 ORDER BY t1} 124} "TF- har ont i\u1234h" 125do_test func-3.6 { 126 execsql {SELECT substr(t1,3,2) FROM tbl1 ORDER BY t1} 127} "F- ar nt \u1234h" 128do_test func-3.7 { 129 execsql {SELECT substr(t1,4,2) FROM tbl1 ORDER BY t1} 130} "-8 ra ta ho" 131do_test func-3.8 { 132 execsql {SELECT substr(t1,-1,1) FROM tbl1 ORDER BY t1} 133} "8 s s o" 134do_test func-3.9 { 135 execsql {SELECT substr(t1,-3,2) FROM tbl1 ORDER BY t1} 136} "F- er in \u1234h" 137do_test func-3.10 { 138 execsql {SELECT substr(t1,-4,3) FROM tbl1 ORDER BY t1} 139} "TF- ter ain i\u1234h" 140do_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} 147 148} ;# End \u1234!=u1234 149 150# 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} 160} {1 {wrong number of arguments to function abs()}} 161do_test func-4.2 { 162 catchsql {SELECT abs() FROM t1} 163} {1 {wrong number of arguments to function abs()}} 164do_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} 169} {0 {3 12345.6789 5}} 170do_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} 175} {0.0 0.0 0.0 0.0 0.0} 176 177do_test func-4.5 { 178 catchsql {SELECT round(a,b,c) FROM t1} 179} {1 {wrong number of arguments to function round()}} 180do_test func-4.6 { 181 catchsql {SELECT round(b,2) FROM t1 ORDER BY b} 182} {0 {-2.0 1.23 2.0}} 183do_test func-4.7 { 184 catchsql {SELECT round(b,0) FROM t1 ORDER BY a} 185} {0 {2.0 1.0 -2.0}} 186do_test func-4.8 { 187 catchsql {SELECT round(c) FROM t1 ORDER BY a} 188} {0 {3.0 -12346.0 -5.0}} 189do_test func-4.9 { 190 catchsql {SELECT round(c,a) FROM t1 ORDER BY a} 191} {0 {3.0 -12345.68 -5.0}} 192do_test func-4.10 { 193 catchsql {SELECT 'x' || round(c,a) || 'y' FROM t1 ORDER BY a} 194} {0 {x3.0y x-12345.68y x-5.0y}} 195do_test func-4.11 { 196 catchsql {SELECT round() FROM t1 ORDER BY a} 197} {1 {wrong number of arguments to function round()}} 198do_test func-4.12 { 199 execsql {SELECT coalesce(round(a,2),'nil') FROM t2} 200} {1.0 nil 345.0 nil 67890.0} 201do_test func-4.13 { 202 execsql {SELECT round(t1,2) FROM tbl1} 203} {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 211 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} 223ifcapable !icu { 224 do_test func-5.4 { 225 catchsql {SELECT upper(a,5) FROM t2} 226 } {1 {wrong number of arguments to function upper()}} 227} 228do_test func-5.5 { 229 catchsql {SELECT upper(*) FROM t2} 230} {1 {wrong number of arguments to function upper()}} 231 232# Test the coalesce() and nullif() functions 233# 234do_test func-6.1 { 235 execsql {SELECT coalesce(a,'xyz') FROM t2} 236} {1 xyz 345 xyz 67890} 237do_test func-6.2 { 238 execsql {SELECT coalesce(upper(a),'nil') FROM t2} 239} {1 nil 345 nil 67890} 240do_test func-6.3 { 241 execsql {SELECT coalesce(nullif(1,1),'nil')} 242} {nil} 243do_test func-6.4 { 244 execsql {SELECT coalesce(nullif(1,2),'nil')} 245} {1} 246do_test func-6.5 { 247 execsql {SELECT coalesce(nullif(1,NULL),'nil')} 248} {1} 249 250 251# Test the last_insert_rowid() function 252# 253do_test func-7.1 { 254 execsql {SELECT last_insert_rowid()} 255} [db last_insert_rowid] 256 257# Tests for aggregate functions and how they handle NULLs. 258# 259do_test func-8.1 { 260 ifcapable explain { 261 execsql {EXPLAIN SELECT sum(a) FROM t2;} 262 } 263 execsql { 264 SELECT sum(a), count(a), round(avg(a),2), min(a), max(a), count(*) FROM t2; 265 } 266} {68236 3 22745.33 1 67890 5} 267do_test func-8.2 { 268 execsql { 269 SELECT max('z+'||a||'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOP') FROM t2; 270 } 271} {z+67890abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOP} 272 273ifcapable tempdb { 274 do_test func-8.3 { 275 execsql { 276 CREATE TEMP TABLE t3 AS SELECT a FROM t2 ORDER BY a DESC; 277 SELECT min('z+'||a||'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOP') FROM t3; 278 } 279 } {z+1abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOP} 280} else { 281 do_test func-8.3 { 282 execsql { 283 CREATE TABLE t3 AS SELECT a FROM t2 ORDER BY a DESC; 284 SELECT min('z+'||a||'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOP') FROM t3; 285 } 286 } {z+1abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOP} 287} 288do_test func-8.4 { 289 execsql { 290 SELECT max('z+'||a||'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOP') FROM t3; 291 } 292} {z+67890abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOP} 293 294# How do you test the random() function in a meaningful, deterministic way? 295# 296do_test func-9.1 { 297 execsql { 298 SELECT random() is not null; 299 } 300} {1} 301do_test func-9.2 { 302 execsql { 303 SELECT typeof(random()); 304 } 305} {integer} 306do_test func-9.3 { 307 execsql { 308 SELECT randomblob(32) is not null; 309 } 310} {1} 311do_test func-9.4 { 312 execsql { 313 SELECT typeof(randomblob(32)); 314 } 315} {blob} 316do_test func-9.5 { 317 execsql { 318 SELECT length(randomblob(32)), length(randomblob(-5)), 319 length(randomblob(2000)) 320 } 321} {32 1 2000} 322 323# The "hex()" function was added in order to be able to render blobs 324# generated by randomblob(). So this seems like a good place to test 325# hex(). 326# 327do_test func-9.10 { 328 execsql {SELECT hex(x'00112233445566778899aAbBcCdDeEfF')} 329} {00112233445566778899AABBCCDDEEFF} 330set encoding [db one {PRAGMA encoding}] 331if {$encoding=="UTF-16le"} { 332 do_test func-9.11-utf16le { 333 execsql {SELECT hex(replace('abcdefg','ef','12'))} 334 } {6100620063006400310032006700} 335 do_test func-9.12-utf16le { 336 execsql {SELECT hex(replace('abcdefg','','12'))} 337 } {{}} 338 breakpoint 339 do_test func-9.13-utf16le { 340 execsql {SELECT hex(replace('aabcdefg','a','aaa'))} 341 } {610061006100610061006100620063006400650066006700} 342} elseif {$encoding=="UTF-8"} { 343 do_test func-9.11-utf8 { 344 execsql {SELECT hex(replace('abcdefg','ef','12'))} 345 } {61626364313267} 346 do_test func-9.12-utf8 { 347 execsql {SELECT hex(replace('abcdefg','','12'))} 348 } {{}} 349 breakpoint 350 do_test func-9.13-utf8 { 351 execsql {SELECT hex(replace('aabcdefg','a','aaa'))} 352 } {616161616161626364656667} 353} 354 355# Use the "sqlite_register_test_function" TCL command which is part of 356# the text fixture in order to verify correct operation of some of 357# the user-defined SQL function APIs that are not used by the built-in 358# functions. 359# 360set ::DB [sqlite3_connection_pointer db] 361sqlite_register_test_function $::DB testfunc 362do_test func-10.1 { 363 catchsql { 364 SELECT testfunc(NULL,NULL); 365 } 366} {1 {first argument should be one of: int int64 string double null value}} 367do_test func-10.2 { 368 execsql { 369 SELECT testfunc( 370 'string', 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ', 371 'int', 1234 372 ); 373 } 374} {1234} 375do_test func-10.3 { 376 execsql { 377 SELECT testfunc( 378 'string', 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ', 379 'string', NULL 380 ); 381 } 382} {{}} 383do_test func-10.4 { 384 execsql { 385 SELECT testfunc( 386 'string', 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ', 387 'double', 1.234 388 ); 389 } 390} {1.234} 391do_test func-10.5 { 392 execsql { 393 SELECT testfunc( 394 'string', 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ', 395 'int', 1234, 396 'string', 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ', 397 'string', NULL, 398 'string', 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ', 399 'double', 1.234, 400 'string', 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ', 401 'int', 1234, 402 'string', 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ', 403 'string', NULL, 404 'string', 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ', 405 'double', 1.234 406 ); 407 } 408} {1.234} 409 410# Test the built-in sqlite_version(*) SQL function. 411# 412do_test func-11.1 { 413 execsql { 414 SELECT sqlite_version(*); 415 } 416} [sqlite3 -version] 417 418# Test that destructors passed to sqlite3 by calls to sqlite3_result_text() 419# etc. are called. These tests use two special user-defined functions 420# (implemented in func.c) only available in test builds. 421# 422# Function test_destructor() takes one argument and returns a copy of the 423# text form of that argument. A destructor is associated with the return 424# value. Function test_destructor_count() returns the number of outstanding 425# destructor calls for values returned by test_destructor(). 426# 427do_test func-12.1 { 428 execsql { 429 SELECT test_destructor('hello world'), test_destructor_count(); 430 } 431} {{hello world} 1} 432do_test func-12.2 { 433 execsql { 434 SELECT test_destructor_count(); 435 } 436} {0} 437do_test func-12.3 { 438 execsql { 439 SELECT test_destructor('hello')||' world', test_destructor_count(); 440 } 441} {{hello world} 0} 442do_test func-12.4 { 443 execsql { 444 SELECT test_destructor_count(); 445 } 446} {0} 447do_test func-12.5 { 448 execsql { 449 CREATE TABLE t4(x); 450 INSERT INTO t4 VALUES(test_destructor('hello')); 451 INSERT INTO t4 VALUES(test_destructor('world')); 452 SELECT min(test_destructor(x)), max(test_destructor(x)) FROM t4; 453 } 454} {hello world} 455do_test func-12.6 { 456 execsql { 457 SELECT test_destructor_count(); 458 } 459} {0} 460do_test func-12.7 { 461 execsql { 462 DROP TABLE t4; 463 } 464} {} 465 466# Test that the auxdata API for scalar functions works. This test uses 467# a special user-defined function only available in test builds, 468# test_auxdata(). Function test_auxdata() takes any number of arguments. 469do_test func-13.1 { 470 execsql { 471 SELECT test_auxdata('hello world'); 472 } 473} {0} 474 475do_test func-13.2 { 476 execsql { 477 CREATE TABLE t4(a, b); 478 INSERT INTO t4 VALUES('abc', 'def'); 479 INSERT INTO t4 VALUES('ghi', 'jkl'); 480 } 481} {} 482do_test func-13.3 { 483 execsql { 484 SELECT test_auxdata('hello world') FROM t4; 485 } 486} {0 1} 487do_test func-13.4 { 488 execsql { 489 SELECT test_auxdata('hello world', 123) FROM t4; 490 } 491} {{0 0} {1 1}} 492do_test func-13.5 { 493 execsql { 494 SELECT test_auxdata('hello world', a) FROM t4; 495 } 496} {{0 0} {1 0}} 497do_test func-13.6 { 498 execsql { 499 SELECT test_auxdata('hello'||'world', a) FROM t4; 500 } 501} {{0 0} {1 0}} 502 503# Test that auxilary data is preserved between calls for SQL variables. 504do_test func-13.7 { 505 set DB [sqlite3_connection_pointer db] 506 set sql "SELECT test_auxdata( ? , a ) FROM t4;" 507 set STMT [sqlite3_prepare $DB $sql -1 TAIL] 508 sqlite3_bind_text $STMT 1 hello -1 509 set res [list] 510 while { "SQLITE_ROW"==[sqlite3_step $STMT] } { 511 lappend res [sqlite3_column_text $STMT 0] 512 } 513 lappend res [sqlite3_finalize $STMT] 514} {{0 0} {1 0} SQLITE_OK} 515 516# Make sure that a function with a very long name is rejected 517do_test func-14.1 { 518 catch { 519 db function [string repeat X 254] {return "hello"} 520 } 521} {0} 522do_test func-14.2 { 523 catch { 524 db function [string repeat X 256] {return "hello"} 525 } 526} {1} 527 528do_test func-15.1 { 529 catchsql { 530 select test_error(NULL); 531 } 532} {1 {}} 533 534# Test the quote function for BLOB and NULL values. 535do_test func-16.1 { 536 execsql { 537 CREATE TABLE tbl2(a, b); 538 } 539 set STMT [sqlite3_prepare $::DB "INSERT INTO tbl2 VALUES(?, ?)" -1 TAIL] 540 sqlite3_bind_blob $::STMT 1 abc 3 541 sqlite3_step $::STMT 542 sqlite3_finalize $::STMT 543 execsql { 544 SELECT quote(a), quote(b) FROM tbl2; 545 } 546} {X'616263' NULL} 547 548# Correctly handle function error messages that include %. Ticket #1354 549# 550do_test func-17.1 { 551 proc testfunc1 args {error "Error %d with %s percents %p"} 552 db function testfunc1 ::testfunc1 553 catchsql { 554 SELECT testfunc1(1,2,3); 555 } 556} {1 {Error %d with %s percents %p}} 557 558# The SUM function should return integer results when all inputs are integer. 559# 560do_test func-18.1 { 561 execsql { 562 CREATE TABLE t5(x); 563 INSERT INTO t5 VALUES(1); 564 INSERT INTO t5 VALUES(-99); 565 INSERT INTO t5 VALUES(10000); 566 SELECT sum(x) FROM t5; 567 } 568} {9902} 569do_test func-18.2 { 570 execsql { 571 INSERT INTO t5 VALUES(0.0); 572 SELECT sum(x) FROM t5; 573 } 574} {9902.0} 575 576# The sum of nothing is NULL. But the sum of all NULLs is NULL. 577# 578# The TOTAL of nothing is 0.0. 579# 580do_test func-18.3 { 581 execsql { 582 DELETE FROM t5; 583 SELECT sum(x), total(x) FROM t5; 584 } 585} {{} 0.0} 586do_test func-18.4 { 587 execsql { 588 INSERT INTO t5 VALUES(NULL); 589 SELECT sum(x), total(x) FROM t5 590 } 591} {{} 0.0} 592do_test func-18.5 { 593 execsql { 594 INSERT INTO t5 VALUES(NULL); 595 SELECT sum(x), total(x) FROM t5 596 } 597} {{} 0.0} 598do_test func-18.6 { 599 execsql { 600 INSERT INTO t5 VALUES(123); 601 SELECT sum(x), total(x) FROM t5 602 } 603} {123 123.0} 604 605# Ticket #1664, #1669, #1670, #1674: An integer overflow on SUM causes 606# an error. The non-standard TOTAL() function continues to give a helpful 607# result. 608# 609do_test func-18.10 { 610 execsql { 611 CREATE TABLE t6(x INTEGER); 612 INSERT INTO t6 VALUES(1); 613 INSERT INTO t6 VALUES(1<<62); 614 SELECT sum(x) - ((1<<62)+1) from t6; 615 } 616} 0 617do_test func-18.11 { 618 execsql { 619 SELECT typeof(sum(x)) FROM t6 620 } 621} integer 622do_test func-18.12 { 623 catchsql { 624 INSERT INTO t6 VALUES(1<<62); 625 SELECT sum(x) - ((1<<62)*2.0+1) from t6; 626 } 627} {1 {integer overflow}} 628do_test func-18.13 { 629 execsql { 630 SELECT total(x) - ((1<<62)*2.0+1) FROM t6 631 } 632} 0.0 633do_test func-18.14 { 634 execsql { 635 SELECT sum(-9223372036854775805); 636 } 637} -9223372036854775805 638 639ifcapable compound&&subquery { 640 641do_test func-18.15 { 642 catchsql { 643 SELECT sum(x) FROM 644 (SELECT 9223372036854775807 AS x UNION ALL 645 SELECT 10 AS x); 646 } 647} {1 {integer overflow}} 648do_test func-18.16 { 649 catchsql { 650 SELECT sum(x) FROM 651 (SELECT 9223372036854775807 AS x UNION ALL 652 SELECT -10 AS x); 653 } 654} {0 9223372036854775797} 655do_test func-18.17 { 656 catchsql { 657 SELECT sum(x) FROM 658 (SELECT -9223372036854775807 AS x UNION ALL 659 SELECT 10 AS x); 660 } 661} {0 -9223372036854775797} 662do_test func-18.18 { 663 catchsql { 664 SELECT sum(x) FROM 665 (SELECT -9223372036854775807 AS x UNION ALL 666 SELECT -10 AS x); 667 } 668} {1 {integer overflow}} 669do_test func-18.19 { 670 catchsql { 671 SELECT sum(x) FROM (SELECT 9 AS x UNION ALL SELECT -10 AS x); 672 } 673} {0 -1} 674do_test func-18.20 { 675 catchsql { 676 SELECT sum(x) FROM (SELECT -9 AS x UNION ALL SELECT 10 AS x); 677 } 678} {0 1} 679do_test func-18.21 { 680 catchsql { 681 SELECT sum(x) FROM (SELECT -10 AS x UNION ALL SELECT 9 AS x); 682 } 683} {0 -1} 684do_test func-18.22 { 685 catchsql { 686 SELECT sum(x) FROM (SELECT 10 AS x UNION ALL SELECT -9 AS x); 687 } 688} {0 1} 689 690} ;# ifcapable compound&&subquery 691 692# Integer overflow on abs() 693# 694do_test func-18.31 { 695 catchsql { 696 SELECT abs(-9223372036854775807); 697 } 698} {0 9223372036854775807} 699do_test func-18.32 { 700 catchsql { 701 SELECT abs(-9223372036854775807-1); 702 } 703} {1 {integer overflow}} 704 705# The MATCH function exists but is only a stub and always throws an error. 706# 707do_test func-19.1 { 708 execsql { 709 SELECT match(a,b) FROM t1 WHERE 0; 710 } 711} {} 712do_test func-19.2 { 713 catchsql { 714 SELECT 'abc' MATCH 'xyz'; 715 } 716} {1 {unable to use function MATCH in the requested context}} 717do_test func-19.3 { 718 catchsql { 719 SELECT 'abc' NOT MATCH 'xyz'; 720 } 721} {1 {unable to use function MATCH in the requested context}} 722do_test func-19.4 { 723 catchsql { 724 SELECT match(1,2,3); 725 } 726} {1 {wrong number of arguments to function match()}} 727 728# Soundex tests. 729# 730if {![catch {db eval {SELECT soundex('hello')}}]} { 731 set i 0 732 foreach {name sdx} { 733 euler E460 734 EULER E460 735 Euler E460 736 ellery E460 737 gauss G200 738 ghosh G200 739 hilbert H416 740 Heilbronn H416 741 knuth K530 742 kant K530 743 Lloyd L300 744 LADD L300 745 Lukasiewicz L222 746 Lissajous L222 747 A A000 748 12345 ?000 749 } { 750 incr i 751 do_test func-20.$i { 752 execsql {SELECT soundex($name)} 753 } $sdx 754 } 755} 756 757# Tests of the REPLACE function. 758# 759do_test func-21.1 { 760 catchsql { 761 SELECT replace(1,2); 762 } 763} {1 {wrong number of arguments to function replace()}} 764do_test func-21.2 { 765 catchsql { 766 SELECT replace(1,2,3,4); 767 } 768} {1 {wrong number of arguments to function replace()}} 769do_test func-21.3 { 770 execsql { 771 SELECT typeof(replace("This is the main test string", NULL, "ALT")); 772 } 773} {null} 774do_test func-21.4 { 775 execsql { 776 SELECT typeof(replace(NULL, "main", "ALT")); 777 } 778} {null} 779do_test func-21.5 { 780 execsql { 781 SELECT typeof(replace("This is the main test string", "main", NULL)); 782 } 783} {null} 784do_test func-21.6 { 785 execsql { 786 SELECT replace("This is the main test string", "main", "ALT"); 787 } 788} {{This is the ALT test string}} 789do_test func-21.7 { 790 execsql { 791 SELECT replace("This is the main test string", "main", "larger-main"); 792 } 793} {{This is the larger-main test string}} 794do_test func-21.8 { 795 execsql { 796 SELECT replace("aaaaaaa", "a", "0123456789"); 797 } 798} {0123456789012345678901234567890123456789012345678901234567890123456789} 799 800do_test func-21.9 { 801 # Attempt to exploit a buffer-overflow that at one time existed 802 # in the REPLACE function. 803 set ::str "[string repeat A 29998]CC[string repeat A 35537]" 804 set ::rep [string repeat B 65536] 805 execsql { 806 SELECT LENGTH(REPLACE($::str, 'C', $::rep)); 807 } 808} [expr 29998 + 2*65536 + 35537] 809 810# Tests for the TRIM, LTRIM and RTRIM functions. 811# 812do_test func-22.1 { 813 catchsql {SELECT trim(1,2,3)} 814} {1 {wrong number of arguments to function trim()}} 815do_test func-22.2 { 816 catchsql {SELECT ltrim(1,2,3)} 817} {1 {wrong number of arguments to function ltrim()}} 818do_test func-22.3 { 819 catchsql {SELECT rtrim(1,2,3)} 820} {1 {wrong number of arguments to function rtrim()}} 821do_test func-22.4 { 822 execsql {SELECT trim(' hi ');} 823} {hi} 824do_test func-22.5 { 825 execsql {SELECT ltrim(' hi ');} 826} {{hi }} 827do_test func-22.6 { 828 execsql {SELECT rtrim(' hi ');} 829} {{ hi}} 830do_test func-22.7 { 831 execsql {SELECT trim(' hi ','xyz');} 832} {{ hi }} 833do_test func-22.8 { 834 execsql {SELECT ltrim(' hi ','xyz');} 835} {{ hi }} 836do_test func-22.9 { 837 execsql {SELECT rtrim(' hi ','xyz');} 838} {{ hi }} 839do_test func-22.10 { 840 execsql {SELECT trim('xyxzy hi zzzy','xyz');} 841} {{ hi }} 842do_test func-22.11 { 843 execsql {SELECT ltrim('xyxzy hi zzzy','xyz');} 844} {{ hi zzzy}} 845do_test func-22.12 { 846 execsql {SELECT rtrim('xyxzy hi zzzy','xyz');} 847} {{xyxzy hi }} 848do_test func-22.13 { 849 execsql {SELECT trim(' hi ','');} 850} {{ hi }} 851if {[db one {PRAGMA encoding}]=="UTF-8"} { 852 do_test func-22.14 { 853 execsql {SELECT hex(trim(x'c280e1bfbff48fbfbf6869',x'6162e1bfbfc280'))} 854 } {F48FBFBF6869} 855 do_test func-22.15 { 856 execsql {SELECT hex(trim(x'6869c280e1bfbff48fbfbf61', 857 x'6162e1bfbfc280f48fbfbf'))} 858 } {6869} 859 do_test func-22.16 { 860 execsql {SELECT hex(trim(x'ceb1ceb2ceb3',x'ceb1'));} 861 } {CEB2CEB3} 862} 863do_test func-22.20 { 864 execsql {SELECT typeof(trim(NULL));} 865} {null} 866do_test func-22.21 { 867 execsql {SELECT typeof(trim(NULL,'xyz'));} 868} {null} 869do_test func-22.22 { 870 execsql {SELECT typeof(trim('hello',NULL));} 871} {null} 872 873finish_test 874