1784141eaSdan# 2010 July 16 2784141eaSdan# 3784141eaSdan# The author disclaims copyright to this source code. In place of 4784141eaSdan# a legal notice, here is a blessing: 5784141eaSdan# 6784141eaSdan# May you do good and not evil. 7784141eaSdan# May you find forgiveness for yourself and forgive others. 8784141eaSdan# May you share freely, never taking more than you give. 9784141eaSdan# 10784141eaSdan#*********************************************************************** 11784141eaSdan# 12784141eaSdan# This file implements tests to verify that the "testable statements" in 13784141eaSdan# the lang_expr.html document are correct. 14784141eaSdan# 15784141eaSdan 16784141eaSdanset testdir [file dirname $argv0] 17784141eaSdansource $testdir/tester.tcl 18784141eaSdansource $testdir/malloc_common.tcl 19784141eaSdan 202f56da3fSdanifcapable !compound { 212f56da3fSdan finish_test 222f56da3fSdan return 232f56da3fSdan} 244336cc45Sdan 254336cc45Sdanproc do_expr_test {tn expr type value} { 264336cc45Sdan uplevel do_execsql_test $tn [list "SELECT typeof($expr), $expr"] [ 274336cc45Sdan list [list $type $value] 284336cc45Sdan ] 294336cc45Sdan} 304336cc45Sdan 314336cc45Sdanproc do_qexpr_test {tn expr value} { 324336cc45Sdan uplevel do_execsql_test $tn [list "SELECT quote($expr)"] [list $value] 334336cc45Sdan} 344336cc45Sdan 35784141eaSdan# Set up three global variables: 36784141eaSdan# 37784141eaSdan# ::opname An array mapping from SQL operator to an easy to parse 38784141eaSdan# name. The names are used as part of test case names. 39784141eaSdan# 40784141eaSdan# ::opprec An array mapping from SQL operator to a numeric 41784141eaSdan# precedence value. Operators that group more tightly 42784141eaSdan# have lower numeric precedences. 43784141eaSdan# 44784141eaSdan# ::oplist A list of all SQL operators supported by SQLite. 45784141eaSdan# 46784141eaSdanforeach {op opn} { 47784141eaSdan || cat * mul / div % mod + add 48784141eaSdan - sub << lshift >> rshift & bitand | bitor 49784141eaSdan < less <= lesseq > more >= moreeq = eq1 50784141eaSdan == eq2 <> ne1 != ne2 IS is LIKE like 51784141eaSdan GLOB glob AND and OR or MATCH match REGEXP regexp 52784141eaSdan {IS NOT} isnt 53784141eaSdan} { 54784141eaSdan set ::opname($op) $opn 55784141eaSdan} 56784141eaSdanset oplist [list] 57784141eaSdanforeach {prec opl} { 58784141eaSdan 1 || 59784141eaSdan 2 {* / %} 60784141eaSdan 3 {+ -} 61784141eaSdan 4 {<< >> & |} 62784141eaSdan 5 {< <= > >=} 63784141eaSdan 6 {= == != <> IS {IS NOT} LIKE GLOB MATCH REGEXP} 64784141eaSdan 7 AND 65784141eaSdan 8 OR 66784141eaSdan} { 67784141eaSdan foreach op $opl { 68784141eaSdan set ::opprec($op) $prec 69784141eaSdan lappend oplist $op 70784141eaSdan } 71784141eaSdan} 72784141eaSdan 73784141eaSdan 74784141eaSdan# Hook in definitions of MATCH and REGEX. The following implementations 75784141eaSdan# cause MATCH and REGEX to behave similarly to the == operator. 76784141eaSdan# 77784141eaSdanproc matchfunc {a b} { return [expr {$a==$b}] } 78784141eaSdanproc regexfunc {a b} { return [expr {$a==$b}] } 79784141eaSdandb func match -argcount 2 matchfunc 80784141eaSdandb func regexp -argcount 2 regexfunc 81784141eaSdan 82784141eaSdan#------------------------------------------------------------------------- 83784141eaSdan# Test cases e_expr-1.* attempt to verify that all binary operators listed 84784141eaSdan# in the documentation exist and that the relative precedences of the 85784141eaSdan# operators are also as the documentation suggests. 86784141eaSdan# 87784141eaSdan# EVIDENCE-OF: R-15514-65163 SQLite understands the following binary 88784141eaSdan# operators, in order from highest to lowest precedence: || * / % + - 89784141eaSdan# << >> & | < <= > >= = == != <> IS IS 90784141eaSdan# NOT IN LIKE GLOB MATCH REGEXP AND OR 91784141eaSdan# 92784141eaSdan# EVIDENCE-OF: R-38759-38789 Operators IS and IS NOT have the same 93784141eaSdan# precedence as =. 94784141eaSdan# 95784141eaSdan 96784141eaSdanunset -nocomplain untested 97784141eaSdanforeach op1 $oplist { 98784141eaSdan foreach op2 $oplist { 99784141eaSdan set untested($op1,$op2) 1 100784141eaSdan foreach {tn A B C} { 101784141eaSdan 1 22 45 66 102784141eaSdan 2 0 0 0 103784141eaSdan 3 0 0 1 104784141eaSdan 4 0 1 0 105784141eaSdan 5 0 1 1 106784141eaSdan 6 1 0 0 107784141eaSdan 7 1 0 1 108784141eaSdan 8 1 1 0 109784141eaSdan 9 1 1 1 110784141eaSdan 10 5 6 1 111784141eaSdan 11 1 5 6 112784141eaSdan 12 1 5 5 113784141eaSdan 13 5 5 1 114784141eaSdan 115784141eaSdan 14 5 2 1 116784141eaSdan 15 1 4 1 117784141eaSdan 16 -1 0 1 118784141eaSdan 17 0 1 -1 119784141eaSdan 120784141eaSdan } { 121784141eaSdan set testname "e_expr-1.$opname($op1).$opname($op2).$tn" 122784141eaSdan 123784141eaSdan # If $op2 groups more tightly than $op1, then the result 124784141eaSdan # of executing $sql1 whould be the same as executing $sql3. 125784141eaSdan # If $op1 groups more tightly, or if $op1 and $op2 have 126784141eaSdan # the same precedence, then executing $sql1 should return 127784141eaSdan # the same value as $sql2. 128784141eaSdan # 129784141eaSdan set sql1 "SELECT $A $op1 $B $op2 $C" 130784141eaSdan set sql2 "SELECT ($A $op1 $B) $op2 $C" 131784141eaSdan set sql3 "SELECT $A $op1 ($B $op2 $C)" 132784141eaSdan 133784141eaSdan set a2 [db one $sql2] 134784141eaSdan set a3 [db one $sql3] 135784141eaSdan 136784141eaSdan do_execsql_test $testname $sql1 [list [ 137bd0c0014Sdan if {$opprec($op2) < $opprec($op1)} {set a3} {set a2} 138784141eaSdan ]] 139784141eaSdan if {$a2 != $a3} { unset -nocomplain untested($op1,$op2) } 140784141eaSdan } 141784141eaSdan } 142784141eaSdan} 143784141eaSdan 144784141eaSdanforeach op {* AND OR + || & |} { unset untested($op,$op) } 145784141eaSdanunset untested(+,-) ;# Since (a+b)-c == a+(b-c) 146784141eaSdanunset untested(*,<<) ;# Since (a*b)<<c == a*(b<<c) 147784141eaSdan 148784141eaSdando_test e_expr-1.1 { array names untested } {} 149784141eaSdan 150784141eaSdan# At one point, test 1.2.2 was failing. Instead of the correct result, it 151784141eaSdan# was returning {1 1 0}. This would seem to indicate that LIKE has the 152784141eaSdan# same precedence as '<'. Which is incorrect. It has lower precedence. 153784141eaSdan# 154784141eaSdando_execsql_test e_expr-1.2.1 { 155784141eaSdan SELECT 0 < 2 LIKE 1, (0 < 2) LIKE 1, 0 < (2 LIKE 1) 156784141eaSdan} {1 1 0} 157784141eaSdando_execsql_test e_expr-1.2.2 { 158784141eaSdan SELECT 0 LIKE 0 < 2, (0 LIKE 0) < 2, 0 LIKE (0 < 2) 159784141eaSdan} {0 1 0} 160784141eaSdan 161784141eaSdan# Showing that LIKE and == have the same precedence 162784141eaSdan# 163784141eaSdando_execsql_test e_expr-1.2.3 { 164784141eaSdan SELECT 2 LIKE 2 == 1, (2 LIKE 2) == 1, 2 LIKE (2 == 1) 165784141eaSdan} {1 1 0} 166784141eaSdando_execsql_test e_expr-1.2.4 { 167784141eaSdan SELECT 2 == 2 LIKE 1, (2 == 2) LIKE 1, 2 == (2 LIKE 1) 168784141eaSdan} {1 1 0} 169784141eaSdan 170784141eaSdan# Showing that < groups more tightly than == (< has higher precedence). 171784141eaSdan# 172784141eaSdando_execsql_test e_expr-1.2.5 { 173784141eaSdan SELECT 0 < 2 == 1, (0 < 2) == 1, 0 < (2 == 1) 174784141eaSdan} {1 1 0} 175784141eaSdando_execsql_test e_expr-1.6 { 176784141eaSdan SELECT 0 == 0 < 2, (0 == 0) < 2, 0 == (0 < 2) 177784141eaSdan} {0 1 0} 178784141eaSdan 179784141eaSdan#------------------------------------------------------------------------- 180784141eaSdan# Check that the four unary prefix operators mentioned in the 181784141eaSdan# documentation exist. 182784141eaSdan# 183784141eaSdan# EVIDENCE-OF: R-13958-53419 Supported unary prefix operators are these: 184784141eaSdan# - + ~ NOT 185784141eaSdan# 186784141eaSdando_execsql_test e_expr-2.1 { SELECT - 10 } {-10} 187784141eaSdando_execsql_test e_expr-2.2 { SELECT + 10 } {10} 188784141eaSdando_execsql_test e_expr-2.3 { SELECT ~ 10 } {-11} 189784141eaSdando_execsql_test e_expr-2.4 { SELECT NOT 10 } {0} 190784141eaSdan 191784141eaSdan#------------------------------------------------------------------------- 192784141eaSdan# Tests for the two statements made regarding the unary + operator. 193784141eaSdan# 194784141eaSdan# EVIDENCE-OF: R-53670-03373 The unary operator + is a no-op. 195784141eaSdan# 196784141eaSdan# EVIDENCE-OF: R-19480-30968 It can be applied to strings, numbers, 197784141eaSdan# blobs or NULL and it always returns a result with the same value as 198784141eaSdan# the operand. 199784141eaSdan# 200784141eaSdanforeach {tn literal type} { 201784141eaSdan 1 'helloworld' text 202784141eaSdan 2 45 integer 203784141eaSdan 3 45.2 real 204784141eaSdan 4 45.0 real 205784141eaSdan 5 X'ABCDEF' blob 206784141eaSdan 6 NULL null 207784141eaSdan} { 208784141eaSdan set sql " SELECT quote( + $literal ), typeof( + $literal) " 209784141eaSdan do_execsql_test e_expr-3.$tn $sql [list $literal $type] 210784141eaSdan} 211784141eaSdan 212784141eaSdan#------------------------------------------------------------------------- 213784141eaSdan# Check that both = and == are both acceptable as the "equals" operator. 214784141eaSdan# Similarly, either != or <> work as the not-equals operator. 215784141eaSdan# 216784141eaSdan# EVIDENCE-OF: R-03679-60639 Equals can be either = or ==. 217784141eaSdan# 218784141eaSdan# EVIDENCE-OF: R-30082-38996 The non-equals operator can be either != or 219784141eaSdan# <>. 220784141eaSdan# 221784141eaSdanforeach {tn literal different} { 222784141eaSdan 1 'helloworld' '12345' 223784141eaSdan 2 22 23 224784141eaSdan 3 'xyz' X'78797A' 225784141eaSdan 4 X'78797A00' 'xyz' 226784141eaSdan} { 227784141eaSdan do_execsql_test e_expr-4.$tn " 228784141eaSdan SELECT $literal = $literal, $literal == $literal, 229784141eaSdan $literal = $different, $literal == $different, 230784141eaSdan $literal = NULL, $literal == NULL, 231784141eaSdan $literal != $literal, $literal <> $literal, 232784141eaSdan $literal != $different, $literal <> $different, 233784141eaSdan $literal != NULL, $literal != NULL 234784141eaSdan 235784141eaSdan " {1 1 0 0 {} {} 0 0 1 1 {} {}} 236784141eaSdan} 237784141eaSdan 238784141eaSdan#------------------------------------------------------------------------- 239784141eaSdan# Test the || operator. 240784141eaSdan# 241784141eaSdan# EVIDENCE-OF: R-44409-62641 The || operator is "concatenate" - it joins 242784141eaSdan# together the two strings of its operands. 243784141eaSdan# 244784141eaSdanforeach {tn a b} { 245784141eaSdan 1 'helloworld' '12345' 246784141eaSdan 2 22 23 247784141eaSdan} { 248784141eaSdan set as [db one "SELECT $a"] 249784141eaSdan set bs [db one "SELECT $b"] 250784141eaSdan 251784141eaSdan do_execsql_test e_expr-5.$tn "SELECT $a || $b" [list "${as}${bs}"] 252784141eaSdan} 253784141eaSdan 254784141eaSdan#------------------------------------------------------------------------- 255784141eaSdan# Test the % operator. 256784141eaSdan# 257923260c8Sdrh# EVIDENCE-OF: R-04223-04352 The operator % outputs the integer value of 258923260c8Sdrh# its left operand modulo its right operand. 259784141eaSdan# 260784141eaSdando_execsql_test e_expr-6.1 {SELECT 72%5} {2} 261784141eaSdando_execsql_test e_expr-6.2 {SELECT 72%-5} {2} 262784141eaSdando_execsql_test e_expr-6.3 {SELECT -72%-5} {-2} 263784141eaSdando_execsql_test e_expr-6.4 {SELECT -72%5} {-2} 264923260c8Sdrhdo_execsql_test e_expr-6.5 {SELECT 72.35%5} {2.0} 265784141eaSdan 266784141eaSdan#------------------------------------------------------------------------- 267784141eaSdan# Test that the results of all binary operators are either numeric or 268784141eaSdan# NULL, except for the || operator, which may evaluate to either a text 269784141eaSdan# value or NULL. 270784141eaSdan# 271784141eaSdan# EVIDENCE-OF: R-20665-17792 The result of any binary operator is either 272784141eaSdan# a numeric value or NULL, except for the || concatenation operator 273784141eaSdan# which always evaluates to either NULL or a text value. 274784141eaSdan# 275784141eaSdanset literals { 276784141eaSdan 1 'abc' 2 'hexadecimal' 3 '' 277784141eaSdan 4 123 5 -123 6 0 278784141eaSdan 7 123.4 8 0.0 9 -123.4 279784141eaSdan 10 X'ABCDEF' 11 X'' 12 X'0000' 280784141eaSdan 13 NULL 281784141eaSdan} 282784141eaSdanforeach op $oplist { 283784141eaSdan foreach {n1 rhs} $literals { 284784141eaSdan foreach {n2 lhs} $literals { 285784141eaSdan 286784141eaSdan set t [db one " SELECT typeof($lhs $op $rhs) "] 287784141eaSdan do_test e_expr-7.$opname($op).$n1.$n2 { 288784141eaSdan expr { 289784141eaSdan ($op=="||" && ($t == "text" || $t == "null")) 290784141eaSdan || ($op!="||" && ($t == "integer" || $t == "real" || $t == "null")) 291784141eaSdan } 292784141eaSdan } 1 293784141eaSdan 294784141eaSdan }} 295784141eaSdan} 296784141eaSdan 297784141eaSdan#------------------------------------------------------------------------- 298784141eaSdan# Test the IS and IS NOT operators. 299784141eaSdan# 300784141eaSdan# EVIDENCE-OF: R-24731-45773 The IS and IS NOT operators work like = and 301784141eaSdan# != except when one or both of the operands are NULL. 302784141eaSdan# 303784141eaSdan# EVIDENCE-OF: R-06325-15315 In this case, if both operands are NULL, 304784141eaSdan# then the IS operator evaluates to 1 (true) and the IS NOT operator 305784141eaSdan# evaluates to 0 (false). 306784141eaSdan# 307784141eaSdan# EVIDENCE-OF: R-19812-36779 If one operand is NULL and the other is 308784141eaSdan# not, then the IS operator evaluates to 0 (false) and the IS NOT 309784141eaSdan# operator is 1 (true). 310784141eaSdan# 311784141eaSdan# EVIDENCE-OF: R-61975-13410 It is not possible for an IS or IS NOT 312784141eaSdan# expression to evaluate to NULL. 313784141eaSdan# 314784141eaSdando_execsql_test e_expr-8.1.1 { SELECT NULL IS NULL } {1} 315784141eaSdando_execsql_test e_expr-8.1.2 { SELECT 'ab' IS NULL } {0} 316784141eaSdando_execsql_test e_expr-8.1.3 { SELECT NULL IS 'ab' } {0} 317784141eaSdando_execsql_test e_expr-8.1.4 { SELECT 'ab' IS 'ab' } {1} 318784141eaSdando_execsql_test e_expr-8.1.5 { SELECT NULL == NULL } {{}} 319784141eaSdando_execsql_test e_expr-8.1.6 { SELECT 'ab' == NULL } {{}} 320784141eaSdando_execsql_test e_expr-8.1.7 { SELECT NULL == 'ab' } {{}} 321784141eaSdando_execsql_test e_expr-8.1.8 { SELECT 'ab' == 'ab' } {1} 322784141eaSdando_execsql_test e_expr-8.1.9 { SELECT NULL IS NOT NULL } {0} 323784141eaSdando_execsql_test e_expr-8.1.10 { SELECT 'ab' IS NOT NULL } {1} 324784141eaSdando_execsql_test e_expr-8.1.11 { SELECT NULL IS NOT 'ab' } {1} 325784141eaSdando_execsql_test e_expr-8.1.12 { SELECT 'ab' IS NOT 'ab' } {0} 326784141eaSdando_execsql_test e_expr-8.1.13 { SELECT NULL != NULL } {{}} 327784141eaSdando_execsql_test e_expr-8.1.14 { SELECT 'ab' != NULL } {{}} 328784141eaSdando_execsql_test e_expr-8.1.15 { SELECT NULL != 'ab' } {{}} 329784141eaSdando_execsql_test e_expr-8.1.16 { SELECT 'ab' != 'ab' } {0} 330784141eaSdan 331784141eaSdanforeach {n1 rhs} $literals { 332784141eaSdan foreach {n2 lhs} $literals { 333784141eaSdan if {$rhs!="NULL" && $lhs!="NULL"} { 334784141eaSdan set eq [execsql "SELECT $lhs = $rhs, $lhs != $rhs"] 335784141eaSdan } else { 336784141eaSdan set eq [list [expr {$lhs=="NULL" && $rhs=="NULL"}] \ 337784141eaSdan [expr {$lhs!="NULL" || $rhs!="NULL"}] 338784141eaSdan ] 339784141eaSdan } 340784141eaSdan set test e_expr-8.2.$n1.$n2 341784141eaSdan do_execsql_test $test.1 "SELECT $lhs IS $rhs, $lhs IS NOT $rhs" $eq 342784141eaSdan do_execsql_test $test.2 " 343784141eaSdan SELECT ($lhs IS $rhs) IS NULL, ($lhs IS NOT $rhs) IS NULL 344784141eaSdan " {0 0} 345784141eaSdan } 346784141eaSdan} 347784141eaSdan 348c29486a2Sdan#------------------------------------------------------------------------- 349c29486a2Sdan# Run some tests on the COLLATE "unary postfix operator". 350c29486a2Sdan# 351c29486a2Sdan# This collation sequence reverses both arguments before using 352c29486a2Sdan# [string compare] to compare them. For example, when comparing the 353c29486a2Sdan# strings 'one' and 'four', return the result of: 354c29486a2Sdan# 355c29486a2Sdan# string compare eno ruof 356c29486a2Sdan# 357c29486a2Sdanproc reverse_str {zStr} { 358c29486a2Sdan set out "" 359c29486a2Sdan foreach c [split $zStr {}] { set out "${c}${out}" } 360c29486a2Sdan set out 361c29486a2Sdan} 362c29486a2Sdanproc reverse_collate {zLeft zRight} { 363c29486a2Sdan string compare [reverse_str $zLeft] [reverse_str $zRight] 364c29486a2Sdan} 365c29486a2Sdandb collate reverse reverse_collate 366c29486a2Sdan 367c29486a2Sdan# EVIDENCE-OF: R-59577-33471 The COLLATE operator is a unary postfix 368c29486a2Sdan# operator that assigns a collating sequence to an expression. 369c29486a2Sdan# 37039759747Sdrh# EVIDENCE-OF: R-36231-30731 The COLLATE operator has a higher 37139759747Sdrh# precedence (binds more tightly) than any binary operator and any unary 37239759747Sdrh# prefix operator except "~". 373c29486a2Sdan# 374c29486a2Sdando_execsql_test e_expr-9.1 { SELECT 'abcd' < 'bbbb' COLLATE reverse } 0 375c29486a2Sdando_execsql_test e_expr-9.2 { SELECT ('abcd' < 'bbbb') COLLATE reverse } 1 376c29486a2Sdando_execsql_test e_expr-9.3 { SELECT 'abcd' <= 'bbbb' COLLATE reverse } 0 377c29486a2Sdando_execsql_test e_expr-9.4 { SELECT ('abcd' <= 'bbbb') COLLATE reverse } 1 378c29486a2Sdan 379c29486a2Sdando_execsql_test e_expr-9.5 { SELECT 'abcd' > 'bbbb' COLLATE reverse } 1 380c29486a2Sdando_execsql_test e_expr-9.6 { SELECT ('abcd' > 'bbbb') COLLATE reverse } 0 381c29486a2Sdando_execsql_test e_expr-9.7 { SELECT 'abcd' >= 'bbbb' COLLATE reverse } 1 382c29486a2Sdando_execsql_test e_expr-9.8 { SELECT ('abcd' >= 'bbbb') COLLATE reverse } 0 383c29486a2Sdan 384c29486a2Sdando_execsql_test e_expr-9.10 { SELECT 'abcd' = 'ABCD' COLLATE nocase } 1 385c29486a2Sdando_execsql_test e_expr-9.11 { SELECT ('abcd' = 'ABCD') COLLATE nocase } 0 386c29486a2Sdando_execsql_test e_expr-9.12 { SELECT 'abcd' == 'ABCD' COLLATE nocase } 1 387c29486a2Sdando_execsql_test e_expr-9.13 { SELECT ('abcd' == 'ABCD') COLLATE nocase } 0 388c29486a2Sdando_execsql_test e_expr-9.14 { SELECT 'abcd' IS 'ABCD' COLLATE nocase } 1 389c29486a2Sdando_execsql_test e_expr-9.15 { SELECT ('abcd' IS 'ABCD') COLLATE nocase } 0 390c29486a2Sdan 391c29486a2Sdando_execsql_test e_expr-9.16 { SELECT 'abcd' != 'ABCD' COLLATE nocase } 0 392c29486a2Sdando_execsql_test e_expr-9.17 { SELECT ('abcd' != 'ABCD') COLLATE nocase } 1 393c29486a2Sdando_execsql_test e_expr-9.18 { SELECT 'abcd' <> 'ABCD' COLLATE nocase } 0 394c29486a2Sdando_execsql_test e_expr-9.19 { SELECT ('abcd' <> 'ABCD') COLLATE nocase } 1 395c29486a2Sdando_execsql_test e_expr-9.20 { SELECT 'abcd' IS NOT 'ABCD' COLLATE nocase } 0 396c29486a2Sdando_execsql_test e_expr-9.21 { SELECT ('abcd' IS NOT 'ABCD') COLLATE nocase } 1 397c29486a2Sdan 398c29486a2Sdando_execsql_test e_expr-9.22 { 399c29486a2Sdan SELECT 'bbb' BETWEEN 'AAA' AND 'CCC' COLLATE nocase 400c29486a2Sdan} 1 401c29486a2Sdando_execsql_test e_expr-9.23 { 402c29486a2Sdan SELECT ('bbb' BETWEEN 'AAA' AND 'CCC') COLLATE nocase 403c29486a2Sdan} 0 404c29486a2Sdan 405c29486a2Sdan# EVIDENCE-OF: R-58731-25439 The collating sequence set by the COLLATE 406c29486a2Sdan# operator overrides the collating sequence determined by the COLLATE 407c29486a2Sdan# clause in a table column definition. 408c29486a2Sdan# 409c29486a2Sdando_execsql_test e_expr-9.24 { 410c29486a2Sdan CREATE TABLE t24(a COLLATE NOCASE, b); 411c29486a2Sdan INSERT INTO t24 VALUES('aaa', 1); 412c29486a2Sdan INSERT INTO t24 VALUES('bbb', 2); 413c29486a2Sdan INSERT INTO t24 VALUES('ccc', 3); 414c29486a2Sdan} {} 415c29486a2Sdando_execsql_test e_expr-9.25 { SELECT 'BBB' = a FROM t24 } {0 1 0} 416c29486a2Sdando_execsql_test e_expr-9.25 { SELECT a = 'BBB' FROM t24 } {0 1 0} 417c29486a2Sdando_execsql_test e_expr-9.25 { SELECT 'BBB' = a COLLATE binary FROM t24 } {0 0 0} 418c29486a2Sdando_execsql_test e_expr-9.25 { SELECT a COLLATE binary = 'BBB' FROM t24 } {0 0 0} 419c29486a2Sdan 420c29486a2Sdan#------------------------------------------------------------------------- 421c29486a2Sdan# Test statements related to literal values. 422c29486a2Sdan# 423c29486a2Sdan# EVIDENCE-OF: R-31536-32008 Literal values may be integers, floating 424c29486a2Sdan# point numbers, strings, BLOBs, or NULLs. 425c29486a2Sdan# 426c29486a2Sdando_execsql_test e_expr-10.1.1 { SELECT typeof(5) } {integer} 427c29486a2Sdando_execsql_test e_expr-10.1.2 { SELECT typeof(5.1) } {real} 428c29486a2Sdando_execsql_test e_expr-10.1.3 { SELECT typeof('5.1') } {text} 429c29486a2Sdando_execsql_test e_expr-10.1.4 { SELECT typeof(X'ABCD') } {blob} 430c29486a2Sdando_execsql_test e_expr-10.1.5 { SELECT typeof(NULL) } {null} 431c29486a2Sdan 43255f1da09Sdan# "Scientific notation is supported for point literal values." 433c29486a2Sdan# 434c29486a2Sdando_execsql_test e_expr-10.2.1 { SELECT typeof(3.4e-02) } {real} 435c29486a2Sdando_execsql_test e_expr-10.2.2 { SELECT typeof(3e+5) } {real} 436c29486a2Sdando_execsql_test e_expr-10.2.3 { SELECT 3.4e-02 } {0.034} 437c29486a2Sdando_execsql_test e_expr-10.2.4 { SELECT 3e+4 } {30000.0} 438c29486a2Sdan 439c29486a2Sdan# EVIDENCE-OF: R-35229-17830 A string constant is formed by enclosing 440c29486a2Sdan# the string in single quotes ('). 441c29486a2Sdan# 442c29486a2Sdan# EVIDENCE-OF: R-07100-06606 A single quote within the string can be 443c29486a2Sdan# encoded by putting two single quotes in a row - as in Pascal. 444c29486a2Sdan# 445c29486a2Sdando_execsql_test e_expr-10.3.1 { SELECT 'is not' } {{is not}} 446c29486a2Sdando_execsql_test e_expr-10.3.2 { SELECT typeof('is not') } {text} 447c29486a2Sdando_execsql_test e_expr-10.3.3 { SELECT 'isn''t' } {isn't} 448c29486a2Sdando_execsql_test e_expr-10.3.4 { SELECT typeof('isn''t') } {text} 449c29486a2Sdan 450c29486a2Sdan# EVIDENCE-OF: R-09593-03321 BLOB literals are string literals 451c29486a2Sdan# containing hexadecimal data and preceded by a single "x" or "X" 452c29486a2Sdan# character. 453c29486a2Sdan# 454e8a537eeSdrh# EVIDENCE-OF: R-19836-11244 Example: X'53514C697465' 455c29486a2Sdan# 456c29486a2Sdando_execsql_test e_expr-10.4.1 { SELECT typeof(X'0123456789ABCDEF') } blob 457c29486a2Sdando_execsql_test e_expr-10.4.2 { SELECT typeof(x'0123456789ABCDEF') } blob 458c29486a2Sdando_execsql_test e_expr-10.4.3 { SELECT typeof(X'0123456789abcdef') } blob 459c29486a2Sdando_execsql_test e_expr-10.4.4 { SELECT typeof(x'0123456789abcdef') } blob 460c29486a2Sdando_execsql_test e_expr-10.4.5 { SELECT typeof(X'53514C697465') } blob 461c29486a2Sdan 462c29486a2Sdan# EVIDENCE-OF: R-23914-51476 A literal value can also be the token 463c29486a2Sdan# "NULL". 464c7d6156dSdan# 465c29486a2Sdando_execsql_test e_expr-10.5.1 { SELECT NULL } {{}} 466c29486a2Sdando_execsql_test e_expr-10.5.2 { SELECT typeof(NULL) } {null} 467c29486a2Sdan 468c7d6156dSdan#------------------------------------------------------------------------- 469c7d6156dSdan# Test statements related to bound parameters 470c7d6156dSdan# 471c7d6156dSdan 472c7d6156dSdanproc parameter_test {tn sql params result} { 473c7d6156dSdan set stmt [sqlite3_prepare_v2 db $sql -1] 474c7d6156dSdan 475c7d6156dSdan foreach {number name} $params { 476c7d6156dSdan set nm [sqlite3_bind_parameter_name $stmt $number] 477c7d6156dSdan do_test $tn.name.$number [list set {} $nm] $name 478c7d6156dSdan sqlite3_bind_int $stmt $number [expr -1 * $number] 479c7d6156dSdan } 480c7d6156dSdan 481c7d6156dSdan sqlite3_step $stmt 482c7d6156dSdan 483c7d6156dSdan set res [list] 484c7d6156dSdan for {set i 0} {$i < [sqlite3_column_count $stmt]} {incr i} { 485c7d6156dSdan lappend res [sqlite3_column_text $stmt $i] 486c7d6156dSdan } 487c7d6156dSdan 488c7d6156dSdan set rc [sqlite3_finalize $stmt] 489c7d6156dSdan do_test $tn.rc [list set {} $rc] SQLITE_OK 490c7d6156dSdan do_test $tn.res [list set {} $res] $result 491c7d6156dSdan} 492c7d6156dSdan 493c7d6156dSdan# EVIDENCE-OF: R-33509-39458 A question mark followed by a number NNN 494c7d6156dSdan# holds a spot for the NNN-th parameter. NNN must be between 1 and 495c7d6156dSdan# SQLITE_MAX_VARIABLE_NUMBER. 496c7d6156dSdan# 497c7d6156dSdanset mvn $SQLITE_MAX_VARIABLE_NUMBER 498c7d6156dSdanparameter_test e_expr-11.1 " 499c7d6156dSdan SELECT ?1, ?123, ?$SQLITE_MAX_VARIABLE_NUMBER, ?123, ?4 500c7d6156dSdan" "1 ?1 123 ?123 $mvn ?$mvn 4 ?4" "-1 -123 -$mvn -123 -4" 501c7d6156dSdan 502c7d6156dSdanset errmsg "variable number must be between ?1 and ?$SQLITE_MAX_VARIABLE_NUMBER" 503c7d6156dSdanforeach {tn param_number} [list \ 504c7d6156dSdan 2 0 \ 505c7d6156dSdan 3 [expr $SQLITE_MAX_VARIABLE_NUMBER+1] \ 506c7d6156dSdan 4 [expr $SQLITE_MAX_VARIABLE_NUMBER+2] \ 507c7d6156dSdan 5 12345678903456789034567890234567890 \ 508c7d6156dSdan 6 2147483648 \ 509c7d6156dSdan 7 2147483649 \ 510c7d6156dSdan 8 4294967296 \ 511c7d6156dSdan 9 4294967297 \ 512c7d6156dSdan 10 9223372036854775808 \ 513c7d6156dSdan 11 9223372036854775809 \ 514c7d6156dSdan 12 18446744073709551616 \ 515c7d6156dSdan 13 18446744073709551617 \ 516c7d6156dSdan] { 517c7d6156dSdan do_catchsql_test e_expr-11.1.$tn "SELECT ?$param_number" [list 1 $errmsg] 518c7d6156dSdan} 519c7d6156dSdan 520c7d6156dSdan# EVIDENCE-OF: R-33670-36097 A question mark that is not followed by a 521c7d6156dSdan# number creates a parameter with a number one greater than the largest 522c7d6156dSdan# parameter number already assigned. 523c7d6156dSdan# 524c7d6156dSdan# EVIDENCE-OF: R-42938-07030 If this means the parameter number is 525c7d6156dSdan# greater than SQLITE_MAX_VARIABLE_NUMBER, it is an error. 526c7d6156dSdan# 527c7d6156dSdanparameter_test e_expr-11.2.1 "SELECT ?" {1 {}} -1 528c7d6156dSdanparameter_test e_expr-11.2.2 "SELECT ?, ?" {1 {} 2 {}} {-1 -2} 529c7d6156dSdanparameter_test e_expr-11.2.3 "SELECT ?5, ?" {5 ?5 6 {}} {-5 -6} 530c7d6156dSdanparameter_test e_expr-11.2.4 "SELECT ?, ?5" {1 {} 5 ?5} {-1 -5} 531c7d6156dSdanparameter_test e_expr-11.2.5 "SELECT ?, ?456, ?" { 532c7d6156dSdan 1 {} 456 ?456 457 {} 533c7d6156dSdan} {-1 -456 -457} 534c7d6156dSdanparameter_test e_expr-11.2.5 "SELECT ?, ?456, ?4, ?" { 535c7d6156dSdan 1 {} 456 ?456 4 ?4 457 {} 536c7d6156dSdan} {-1 -456 -4 -457} 537c7d6156dSdanforeach {tn sql} [list \ 538c7d6156dSdan 1 "SELECT ?$mvn, ?" \ 539c7d6156dSdan 2 "SELECT ?[expr $mvn-5], ?, ?, ?, ?, ?, ?" \ 540c7d6156dSdan 3 "SELECT ?[expr $mvn], ?5, ?6, ?" \ 541c7d6156dSdan] { 542c7d6156dSdan do_catchsql_test e_expr-11.3.$tn $sql [list 1 {too many SQL variables}] 543c7d6156dSdan} 544c7d6156dSdan 545c7d6156dSdan# EVIDENCE-OF: R-11620-22743 A colon followed by an identifier name 546c7d6156dSdan# holds a spot for a named parameter with the name :AAAA. 547c7d6156dSdan# 548c7d6156dSdan# Identifiers in SQLite consist of alphanumeric, '_' and '$' characters, 549c7d6156dSdan# and any UTF characters with codepoints larger than 127 (non-ASCII 550c7d6156dSdan# characters). 551c7d6156dSdan# 552c7d6156dSdanparameter_test e_expr-11.2.1 {SELECT :AAAA} {1 :AAAA} -1 553c7d6156dSdanparameter_test e_expr-11.2.2 {SELECT :123} {1 :123} -1 554c7d6156dSdanparameter_test e_expr-11.2.3 {SELECT :__} {1 :__} -1 555c7d6156dSdanparameter_test e_expr-11.2.4 {SELECT :_$_} {1 :_$_} -1 556c7d6156dSdanparameter_test e_expr-11.2.5 " 557c7d6156dSdan SELECT :\u0e40\u0e2d\u0e28\u0e02\u0e39\u0e40\u0e2d\u0e25 558c7d6156dSdan" "1 :\u0e40\u0e2d\u0e28\u0e02\u0e39\u0e40\u0e2d\u0e25" -1 559c7d6156dSdanparameter_test e_expr-11.2.6 "SELECT :\u0080" "1 :\u0080" -1 560c7d6156dSdan 561c7d6156dSdan# EVIDENCE-OF: R-49783-61279 An "at" sign works exactly like a colon, 562c7d6156dSdan# except that the name of the parameter created is @AAAA. 563c7d6156dSdan# 564c7d6156dSdanparameter_test e_expr-11.3.1 {SELECT @AAAA} {1 @AAAA} -1 565c7d6156dSdanparameter_test e_expr-11.3.2 {SELECT @123} {1 @123} -1 566c7d6156dSdanparameter_test e_expr-11.3.3 {SELECT @__} {1 @__} -1 567c7d6156dSdanparameter_test e_expr-11.3.4 {SELECT @_$_} {1 @_$_} -1 568c7d6156dSdanparameter_test e_expr-11.3.5 " 569c7d6156dSdan SELECT @\u0e40\u0e2d\u0e28\u0e02\u0e39\u0e40\u0e2d\u0e25 570c7d6156dSdan" "1 @\u0e40\u0e2d\u0e28\u0e02\u0e39\u0e40\u0e2d\u0e25" -1 571c7d6156dSdanparameter_test e_expr-11.3.6 "SELECT @\u0080" "1 @\u0080" -1 572c7d6156dSdan 573c7d6156dSdan# EVIDENCE-OF: R-62610-51329 A dollar-sign followed by an identifier 574c7d6156dSdan# name also holds a spot for a named parameter with the name $AAAA. 575c7d6156dSdan# 576c7d6156dSdan# EVIDENCE-OF: R-55025-21042 The identifier name in this case can 577c7d6156dSdan# include one or more occurrences of "::" and a suffix enclosed in 578c7d6156dSdan# "(...)" containing any text at all. 579c7d6156dSdan# 580c7d6156dSdan# Note: Looks like an identifier cannot consist entirely of "::" 581c7d6156dSdan# characters or just a suffix. Also, the other named variable characters 582c7d6156dSdan# (: and @) work the same way internally. Why not just document it that way? 583c7d6156dSdan# 584c7d6156dSdanparameter_test e_expr-11.4.1 {SELECT $AAAA} {1 $AAAA} -1 585c7d6156dSdanparameter_test e_expr-11.4.2 {SELECT $123} {1 $123} -1 586c7d6156dSdanparameter_test e_expr-11.4.3 {SELECT $__} {1 $__} -1 587c7d6156dSdanparameter_test e_expr-11.4.4 {SELECT $_$_} {1 $_$_} -1 588c7d6156dSdanparameter_test e_expr-11.4.5 " 589c7d6156dSdan SELECT \$\u0e40\u0e2d\u0e28\u0e02\u0e39\u0e40\u0e2d\u0e25 590c7d6156dSdan" "1 \$\u0e40\u0e2d\u0e28\u0e02\u0e39\u0e40\u0e2d\u0e25" -1 591c7d6156dSdanparameter_test e_expr-11.4.6 "SELECT \$\u0080" "1 \$\u0080" -1 592c7d6156dSdan 593c7d6156dSdanparameter_test e_expr-11.5.1 {SELECT $::::a(++--++)} {1 $::::a(++--++)} -1 594c7d6156dSdanparameter_test e_expr-11.5.2 {SELECT $::a()} {1 $::a()} -1 595c7d6156dSdanparameter_test e_expr-11.5.3 {SELECT $::1(::#$)} {1 $::1(::#$)} -1 596c7d6156dSdan 597c7d6156dSdan# EVIDENCE-OF: R-11370-04520 Named parameters are also numbered. The 598c7d6156dSdan# number assigned is one greater than the largest parameter number 599c7d6156dSdan# already assigned. 600c7d6156dSdan# 601c7d6156dSdan# EVIDENCE-OF: R-42620-22184 If this means the parameter would be 602c7d6156dSdan# assigned a number greater than SQLITE_MAX_VARIABLE_NUMBER, it is an 603c7d6156dSdan# error. 604c7d6156dSdan# 605c7d6156dSdanparameter_test e_expr-11.6.1 "SELECT ?, @abc" {1 {} 2 @abc} {-1 -2} 606c7d6156dSdanparameter_test e_expr-11.6.2 "SELECT ?123, :a1" {123 ?123 124 :a1} {-123 -124} 607c7d6156dSdanparameter_test e_expr-11.6.3 {SELECT $a, ?8, ?, $b, ?2, $c} { 608c7d6156dSdan 1 $a 8 ?8 9 {} 10 $b 2 ?2 11 $c 609c7d6156dSdan} {-1 -8 -9 -10 -2 -11} 610c7d6156dSdanforeach {tn sql} [list \ 611c7d6156dSdan 1 "SELECT ?$mvn, \$::a" \ 612c7d6156dSdan 2 "SELECT ?$mvn, ?4, @a1" \ 613c7d6156dSdan 3 "SELECT ?[expr $mvn-2], :bag, @123, \$x" \ 614c7d6156dSdan] { 615c7d6156dSdan do_catchsql_test e_expr-11.7.$tn $sql [list 1 {too many SQL variables}] 616c7d6156dSdan} 617c7d6156dSdan 6181afca9b7Sdan# EVIDENCE-OF: R-14068-49671 Parameters that are not assigned values 6191afca9b7Sdan# using sqlite3_bind() are treated as NULL. 6201afca9b7Sdan# 6211afca9b7Sdando_test e_expr-11.7.1 { 6221afca9b7Sdan set stmt [sqlite3_prepare_v2 db { SELECT ?, :a, @b, $d } -1] 6231afca9b7Sdan sqlite3_step $stmt 6241afca9b7Sdan 6251afca9b7Sdan list [sqlite3_column_type $stmt 0] \ 6261afca9b7Sdan [sqlite3_column_type $stmt 1] \ 6271afca9b7Sdan [sqlite3_column_type $stmt 2] \ 6281afca9b7Sdan [sqlite3_column_type $stmt 3] 6291afca9b7Sdan} {NULL NULL NULL NULL} 6301afca9b7Sdando_test e_expr-11.7.1 { sqlite3_finalize $stmt } SQLITE_OK 6311afca9b7Sdan 632994e9403Sdan#------------------------------------------------------------------------- 633994e9403Sdan# "Test" the syntax diagrams in lang_expr.html. 634994e9403Sdan# 63539759747Sdrh# -- syntax diagram signed-number 636994e9403Sdan# 637994e9403Sdando_execsql_test e_expr-12.1.1 { SELECT 0, +0, -0 } {0 0 0} 638994e9403Sdando_execsql_test e_expr-12.1.2 { SELECT 1, +1, -1 } {1 1 -1} 639994e9403Sdando_execsql_test e_expr-12.1.3 { SELECT 2, +2, -2 } {2 2 -2} 640994e9403Sdando_execsql_test e_expr-12.1.4 { 641994e9403Sdan SELECT 1.4, +1.4, -1.4 642994e9403Sdan} {1.4 1.4 -1.4} 643994e9403Sdando_execsql_test e_expr-12.1.5 { 644994e9403Sdan SELECT 1.5e+5, +1.5e+5, -1.5e+5 645994e9403Sdan} {150000.0 150000.0 -150000.0} 646994e9403Sdando_execsql_test e_expr-12.1.6 { 647994e9403Sdan SELECT 0.0001, +0.0001, -0.0001 648994e9403Sdan} {0.0001 0.0001 -0.0001} 649994e9403Sdan 65039759747Sdrh# -- syntax diagram literal-value 651994e9403Sdan# 652994e9403Sdanset sqlite_current_time 1 653994e9403Sdando_execsql_test e_expr-12.2.1 {SELECT 123} {123} 654994e9403Sdando_execsql_test e_expr-12.2.2 {SELECT 123.4e05} {12340000.0} 655994e9403Sdando_execsql_test e_expr-12.2.3 {SELECT 'abcde'} {abcde} 656994e9403Sdando_execsql_test e_expr-12.2.4 {SELECT X'414243'} {ABC} 657994e9403Sdando_execsql_test e_expr-12.2.5 {SELECT NULL} {{}} 658994e9403Sdando_execsql_test e_expr-12.2.6 {SELECT CURRENT_TIME} {00:00:01} 659994e9403Sdando_execsql_test e_expr-12.2.7 {SELECT CURRENT_DATE} {1970-01-01} 660994e9403Sdando_execsql_test e_expr-12.2.8 {SELECT CURRENT_TIMESTAMP} {{1970-01-01 00:00:01}} 661994e9403Sdanset sqlite_current_time 0 662994e9403Sdan 66339759747Sdrh# -- syntax diagram expr 664994e9403Sdan# 665fda06befSmistachkinforcedelete test.db2 666994e9403Sdanexecsql { 667994e9403Sdan ATTACH 'test.db2' AS dbname; 668994e9403Sdan CREATE TABLE dbname.tblname(cname); 669994e9403Sdan} 670994e9403Sdan 671994e9403Sdanproc glob {args} {return 1} 672994e9403Sdandb function glob glob 673994e9403Sdandb function match glob 674994e9403Sdandb function regexp glob 675994e9403Sdan 676994e9403Sdanforeach {tn expr} { 677994e9403Sdan 1 123 678994e9403Sdan 2 123.4e05 679994e9403Sdan 3 'abcde' 680994e9403Sdan 4 X'414243' 681994e9403Sdan 5 NULL 682994e9403Sdan 6 CURRENT_TIME 683994e9403Sdan 7 CURRENT_DATE 684994e9403Sdan 8 CURRENT_TIMESTAMP 685994e9403Sdan 686994e9403Sdan 9 ? 687994e9403Sdan 10 ?123 688994e9403Sdan 11 @hello 689994e9403Sdan 12 :world 690994e9403Sdan 13 $tcl 691994e9403Sdan 14 $tcl(array) 692994e9403Sdan 693994e9403Sdan 15 cname 694994e9403Sdan 16 tblname.cname 695994e9403Sdan 17 dbname.tblname.cname 696994e9403Sdan 697994e9403Sdan 18 "+ EXPR" 698994e9403Sdan 19 "- EXPR" 699994e9403Sdan 20 "NOT EXPR" 700994e9403Sdan 21 "~ EXPR" 701994e9403Sdan 702994e9403Sdan 22 "EXPR1 || EXPR2" 703994e9403Sdan 23 "EXPR1 * EXPR2" 704994e9403Sdan 24 "EXPR1 / EXPR2" 705994e9403Sdan 25 "EXPR1 % EXPR2" 706994e9403Sdan 26 "EXPR1 + EXPR2" 707994e9403Sdan 27 "EXPR1 - EXPR2" 708994e9403Sdan 28 "EXPR1 << EXPR2" 709994e9403Sdan 29 "EXPR1 >> EXPR2" 710994e9403Sdan 30 "EXPR1 & EXPR2" 711994e9403Sdan 31 "EXPR1 | EXPR2" 712994e9403Sdan 32 "EXPR1 < EXPR2" 713994e9403Sdan 33 "EXPR1 <= EXPR2" 714994e9403Sdan 34 "EXPR1 > EXPR2" 715994e9403Sdan 35 "EXPR1 >= EXPR2" 716994e9403Sdan 36 "EXPR1 = EXPR2" 717994e9403Sdan 37 "EXPR1 == EXPR2" 718994e9403Sdan 38 "EXPR1 != EXPR2" 719994e9403Sdan 39 "EXPR1 <> EXPR2" 720994e9403Sdan 40 "EXPR1 IS EXPR2" 721994e9403Sdan 41 "EXPR1 IS NOT EXPR2" 722994e9403Sdan 42 "EXPR1 AND EXPR2" 723994e9403Sdan 43 "EXPR1 OR EXPR2" 724994e9403Sdan 725994e9403Sdan 44 "count(*)" 726994e9403Sdan 45 "count(DISTINCT EXPR)" 727994e9403Sdan 46 "substr(EXPR, 10, 20)" 728994e9403Sdan 47 "changes()" 729994e9403Sdan 730994e9403Sdan 48 "( EXPR )" 731994e9403Sdan 732994e9403Sdan 49 "CAST ( EXPR AS integer )" 733994e9403Sdan 50 "CAST ( EXPR AS 'abcd' )" 734994e9403Sdan 51 "CAST ( EXPR AS 'ab$ $cd' )" 735994e9403Sdan 736994e9403Sdan 52 "EXPR COLLATE nocase" 737994e9403Sdan 53 "EXPR COLLATE binary" 738994e9403Sdan 739994e9403Sdan 54 "EXPR1 LIKE EXPR2" 740994e9403Sdan 55 "EXPR1 LIKE EXPR2 ESCAPE EXPR" 741994e9403Sdan 56 "EXPR1 GLOB EXPR2" 742994e9403Sdan 57 "EXPR1 GLOB EXPR2 ESCAPE EXPR" 743994e9403Sdan 58 "EXPR1 REGEXP EXPR2" 744994e9403Sdan 59 "EXPR1 REGEXP EXPR2 ESCAPE EXPR" 745994e9403Sdan 60 "EXPR1 MATCH EXPR2" 746994e9403Sdan 61 "EXPR1 MATCH EXPR2 ESCAPE EXPR" 747994e9403Sdan 62 "EXPR1 NOT LIKE EXPR2" 748994e9403Sdan 63 "EXPR1 NOT LIKE EXPR2 ESCAPE EXPR" 749994e9403Sdan 64 "EXPR1 NOT GLOB EXPR2" 750994e9403Sdan 65 "EXPR1 NOT GLOB EXPR2 ESCAPE EXPR" 751994e9403Sdan 66 "EXPR1 NOT REGEXP EXPR2" 752994e9403Sdan 67 "EXPR1 NOT REGEXP EXPR2 ESCAPE EXPR" 753994e9403Sdan 68 "EXPR1 NOT MATCH EXPR2" 754994e9403Sdan 69 "EXPR1 NOT MATCH EXPR2 ESCAPE EXPR" 755994e9403Sdan 756994e9403Sdan 70 "EXPR ISNULL" 757994e9403Sdan 71 "EXPR NOTNULL" 758994e9403Sdan 72 "EXPR NOT NULL" 759994e9403Sdan 760994e9403Sdan 73 "EXPR1 IS EXPR2" 761994e9403Sdan 74 "EXPR1 IS NOT EXPR2" 762994e9403Sdan 763994e9403Sdan 75 "EXPR NOT BETWEEN EXPR1 AND EXPR2" 764994e9403Sdan 76 "EXPR BETWEEN EXPR1 AND EXPR2" 765994e9403Sdan 766994e9403Sdan 77 "EXPR NOT IN (SELECT cname FROM tblname)" 767994e9403Sdan 78 "EXPR NOT IN (1)" 768994e9403Sdan 79 "EXPR NOT IN (1, 2, 3)" 769994e9403Sdan 80 "EXPR NOT IN tblname" 770994e9403Sdan 81 "EXPR NOT IN dbname.tblname" 771994e9403Sdan 82 "EXPR IN (SELECT cname FROM tblname)" 772994e9403Sdan 83 "EXPR IN (1)" 773994e9403Sdan 84 "EXPR IN (1, 2, 3)" 774994e9403Sdan 85 "EXPR IN tblname" 775994e9403Sdan 86 "EXPR IN dbname.tblname" 776994e9403Sdan 777994e9403Sdan 87 "EXISTS (SELECT cname FROM tblname)" 778994e9403Sdan 88 "NOT EXISTS (SELECT cname FROM tblname)" 779994e9403Sdan 780994e9403Sdan 89 "CASE EXPR WHEN EXPR1 THEN EXPR2 ELSE EXPR END" 781994e9403Sdan 90 "CASE EXPR WHEN EXPR1 THEN EXPR2 END" 782994e9403Sdan 91 "CASE EXPR WHEN EXPR1 THEN EXPR2 WHEN EXPR THEN EXPR1 ELSE EXPR2 END" 783994e9403Sdan 92 "CASE EXPR WHEN EXPR1 THEN EXPR2 WHEN EXPR THEN EXPR1 END" 784994e9403Sdan 93 "CASE WHEN EXPR1 THEN EXPR2 ELSE EXPR END" 785994e9403Sdan 94 "CASE WHEN EXPR1 THEN EXPR2 END" 786994e9403Sdan 95 "CASE WHEN EXPR1 THEN EXPR2 WHEN EXPR THEN EXPR1 ELSE EXPR2 END" 787994e9403Sdan 96 "CASE WHEN EXPR1 THEN EXPR2 WHEN EXPR THEN EXPR1 END" 788994e9403Sdan} { 789994e9403Sdan 790994e9403Sdan # If the expression string being parsed contains "EXPR2", then replace 791994e9403Sdan # string "EXPR1" and "EXPR2" with arbitrary SQL expressions. If it 792994e9403Sdan # contains "EXPR", then replace EXPR with an arbitrary SQL expression. 793994e9403Sdan # 794994e9403Sdan set elist [list $expr] 795994e9403Sdan if {[string match *EXPR2* $expr]} { 796994e9403Sdan set elist [list] 797994e9403Sdan foreach {e1 e2} { cname "34+22" } { 798994e9403Sdan lappend elist [string map [list EXPR1 $e1 EXPR2 $e2] $expr] 799994e9403Sdan } 800994e9403Sdan } 801994e9403Sdan if {[string match *EXPR* $expr]} { 802994e9403Sdan set elist2 [list] 803994e9403Sdan foreach el $elist { 804994e9403Sdan foreach e { cname "34+22" } { 805994e9403Sdan lappend elist2 [string map [list EXPR $e] $el] 806994e9403Sdan } 807994e9403Sdan } 808994e9403Sdan set elist $elist2 809994e9403Sdan } 810994e9403Sdan 811994e9403Sdan set x 0 812994e9403Sdan foreach e $elist { 813994e9403Sdan incr x 814994e9403Sdan do_test e_expr-12.3.$tn.$x { 815994e9403Sdan set rc [catch { execsql "SELECT $e FROM tblname" } msg] 816994e9403Sdan } {0} 817994e9403Sdan } 818994e9403Sdan} 819994e9403Sdan 82039759747Sdrh# -- syntax diagram raise-function 821994e9403Sdan# 822994e9403Sdanforeach {tn raiseexpr} { 823994e9403Sdan 1 "RAISE(IGNORE)" 824994e9403Sdan 2 "RAISE(ROLLBACK, 'error message')" 825994e9403Sdan 3 "RAISE(ABORT, 'error message')" 826994e9403Sdan 4 "RAISE(FAIL, 'error message')" 827994e9403Sdan} { 828994e9403Sdan do_execsql_test e_expr-12.4.$tn " 829994e9403Sdan CREATE TRIGGER dbname.tr$tn BEFORE DELETE ON tblname BEGIN 830994e9403Sdan SELECT $raiseexpr ; 831994e9403Sdan END; 832994e9403Sdan " {} 833994e9403Sdan} 834994e9403Sdan 83573625ec3Sdan#------------------------------------------------------------------------- 83673625ec3Sdan# Test the statements related to the BETWEEN operator. 83773625ec3Sdan# 83873625ec3Sdan# EVIDENCE-OF: R-40079-54503 The BETWEEN operator is logically 83973625ec3Sdan# equivalent to a pair of comparisons. "x BETWEEN y AND z" is equivalent 84073625ec3Sdan# to "x>=y AND x<=z" except that with BETWEEN, the x expression is 84173625ec3Sdan# only evaluated once. 84273625ec3Sdan# 84373625ec3Sdandb func x x 84473625ec3Sdanproc x {} { incr ::xcount ; return [expr $::x] } 84573625ec3Sdanforeach {tn x expr res nEval} { 84673625ec3Sdan 1 10 "x() >= 5 AND x() <= 15" 1 2 84773625ec3Sdan 2 10 "x() BETWEEN 5 AND 15" 1 1 84873625ec3Sdan 84973625ec3Sdan 3 5 "x() >= 5 AND x() <= 5" 1 2 85073625ec3Sdan 4 5 "x() BETWEEN 5 AND 5" 1 1 85112abf408Sdrh 85212abf408Sdrh 5 9 "(x(),8) >= (9,7) AND (x(),8)<=(9,10)" 1 2 85312abf408Sdrh 6 9 "(x(),8) BETWEEN (9,7) AND (9,10)" 1 1 85473625ec3Sdan} { 85573625ec3Sdan do_test e_expr-13.1.$tn { 85673625ec3Sdan set ::xcount 0 85773625ec3Sdan set a [execsql "SELECT $expr"] 85873625ec3Sdan list $::xcount $a 85973625ec3Sdan } [list $nEval $res] 86073625ec3Sdan} 86173625ec3Sdan 86273625ec3Sdan# EVIDENCE-OF: R-05155-34454 The precedence of the BETWEEN operator is 86373625ec3Sdan# the same as the precedence as operators == and != and LIKE and groups 86473625ec3Sdan# left to right. 86573625ec3Sdan# 86673625ec3Sdan# Therefore, BETWEEN groups more tightly than operator "AND", but less 86773625ec3Sdan# so than "<". 86873625ec3Sdan# 86973625ec3Sdando_execsql_test e_expr-13.2.1 { SELECT 1 == 10 BETWEEN 0 AND 2 } 1 87073625ec3Sdando_execsql_test e_expr-13.2.2 { SELECT (1 == 10) BETWEEN 0 AND 2 } 1 87173625ec3Sdando_execsql_test e_expr-13.2.3 { SELECT 1 == (10 BETWEEN 0 AND 2) } 0 87273625ec3Sdando_execsql_test e_expr-13.2.4 { SELECT 6 BETWEEN 4 AND 8 == 1 } 1 87373625ec3Sdando_execsql_test e_expr-13.2.5 { SELECT (6 BETWEEN 4 AND 8) == 1 } 1 87473625ec3Sdando_execsql_test e_expr-13.2.6 { SELECT 6 BETWEEN 4 AND (8 == 1) } 0 87573625ec3Sdan 87673625ec3Sdando_execsql_test e_expr-13.2.7 { SELECT 5 BETWEEN 0 AND 0 != 1 } 1 87773625ec3Sdando_execsql_test e_expr-13.2.8 { SELECT (5 BETWEEN 0 AND 0) != 1 } 1 87873625ec3Sdando_execsql_test e_expr-13.2.9 { SELECT 5 BETWEEN 0 AND (0 != 1) } 0 87973625ec3Sdando_execsql_test e_expr-13.2.10 { SELECT 1 != 0 BETWEEN 0 AND 2 } 1 88073625ec3Sdando_execsql_test e_expr-13.2.11 { SELECT (1 != 0) BETWEEN 0 AND 2 } 1 88173625ec3Sdando_execsql_test e_expr-13.2.12 { SELECT 1 != (0 BETWEEN 0 AND 2) } 0 88273625ec3Sdan 88373625ec3Sdando_execsql_test e_expr-13.2.13 { SELECT 1 LIKE 10 BETWEEN 0 AND 2 } 1 88473625ec3Sdando_execsql_test e_expr-13.2.14 { SELECT (1 LIKE 10) BETWEEN 0 AND 2 } 1 88573625ec3Sdando_execsql_test e_expr-13.2.15 { SELECT 1 LIKE (10 BETWEEN 0 AND 2) } 0 88673625ec3Sdando_execsql_test e_expr-13.2.16 { SELECT 6 BETWEEN 4 AND 8 LIKE 1 } 1 88773625ec3Sdando_execsql_test e_expr-13.2.17 { SELECT (6 BETWEEN 4 AND 8) LIKE 1 } 1 88873625ec3Sdando_execsql_test e_expr-13.2.18 { SELECT 6 BETWEEN 4 AND (8 LIKE 1) } 0 88973625ec3Sdan 89073625ec3Sdando_execsql_test e_expr-13.2.19 { SELECT 0 AND 0 BETWEEN 0 AND 1 } 0 89173625ec3Sdando_execsql_test e_expr-13.2.20 { SELECT 0 AND (0 BETWEEN 0 AND 1) } 0 89273625ec3Sdando_execsql_test e_expr-13.2.21 { SELECT (0 AND 0) BETWEEN 0 AND 1 } 1 89373625ec3Sdando_execsql_test e_expr-13.2.22 { SELECT 0 BETWEEN -1 AND 1 AND 0 } 0 89473625ec3Sdando_execsql_test e_expr-13.2.23 { SELECT (0 BETWEEN -1 AND 1) AND 0 } 0 89573625ec3Sdando_execsql_test e_expr-13.2.24 { SELECT 0 BETWEEN -1 AND (1 AND 0) } 1 89673625ec3Sdan 89773625ec3Sdando_execsql_test e_expr-13.2.25 { SELECT 2 < 3 BETWEEN 0 AND 1 } 1 89873625ec3Sdando_execsql_test e_expr-13.2.26 { SELECT (2 < 3) BETWEEN 0 AND 1 } 1 89973625ec3Sdando_execsql_test e_expr-13.2.27 { SELECT 2 < (3 BETWEEN 0 AND 1) } 0 90073625ec3Sdando_execsql_test e_expr-13.2.28 { SELECT 2 BETWEEN 1 AND 2 < 3 } 0 90173625ec3Sdando_execsql_test e_expr-13.2.29 { SELECT 2 BETWEEN 1 AND (2 < 3) } 0 90273625ec3Sdando_execsql_test e_expr-13.2.30 { SELECT (2 BETWEEN 1 AND 2) < 3 } 1 903f5d3df40Sdan 904f5d3df40Sdan#------------------------------------------------------------------------- 905f5d3df40Sdan# Test the statements related to the LIKE and GLOB operators. 906f5d3df40Sdan# 907f5d3df40Sdan# EVIDENCE-OF: R-16584-60189 The LIKE operator does a pattern matching 908f5d3df40Sdan# comparison. 909f5d3df40Sdan# 910f5d3df40Sdan# EVIDENCE-OF: R-11295-04657 The operand to the right of the LIKE 911f5d3df40Sdan# operator contains the pattern and the left hand operand contains the 912f5d3df40Sdan# string to match against the pattern. 913f5d3df40Sdan# 914f5d3df40Sdando_execsql_test e_expr-14.1.1 { SELECT 'abc%' LIKE 'abcde' } 0 915f5d3df40Sdando_execsql_test e_expr-14.1.2 { SELECT 'abcde' LIKE 'abc%' } 1 916f5d3df40Sdan 917f5d3df40Sdan# EVIDENCE-OF: R-55406-38524 A percent symbol ("%") in the LIKE pattern 918f5d3df40Sdan# matches any sequence of zero or more characters in the string. 919f5d3df40Sdan# 920f5d3df40Sdando_execsql_test e_expr-14.2.1 { SELECT 'abde' LIKE 'ab%de' } 1 921f5d3df40Sdando_execsql_test e_expr-14.2.2 { SELECT 'abXde' LIKE 'ab%de' } 1 922f5d3df40Sdando_execsql_test e_expr-14.2.3 { SELECT 'abABCde' LIKE 'ab%de' } 1 923f5d3df40Sdan 924f5d3df40Sdan# EVIDENCE-OF: R-30433-25443 An underscore ("_") in the LIKE pattern 925f5d3df40Sdan# matches any single character in the string. 926f5d3df40Sdan# 927f5d3df40Sdando_execsql_test e_expr-14.3.1 { SELECT 'abde' LIKE 'ab_de' } 0 928f5d3df40Sdando_execsql_test e_expr-14.3.2 { SELECT 'abXde' LIKE 'ab_de' } 1 929f5d3df40Sdando_execsql_test e_expr-14.3.3 { SELECT 'abABCde' LIKE 'ab_de' } 0 930f5d3df40Sdan 931f5d3df40Sdan# EVIDENCE-OF: R-59007-20454 Any other character matches itself or its 932f5d3df40Sdan# lower/upper case equivalent (i.e. case-insensitive matching). 933f5d3df40Sdan# 934f5d3df40Sdando_execsql_test e_expr-14.4.1 { SELECT 'abc' LIKE 'aBc' } 1 935f5d3df40Sdando_execsql_test e_expr-14.4.2 { SELECT 'aBc' LIKE 'aBc' } 1 936f5d3df40Sdando_execsql_test e_expr-14.4.3 { SELECT 'ac' LIKE 'aBc' } 0 937f5d3df40Sdan 938f5d3df40Sdan# EVIDENCE-OF: R-23648-58527 SQLite only understands upper/lower case 939f5d3df40Sdan# for ASCII characters by default. 940f5d3df40Sdan# 941f5d3df40Sdan# EVIDENCE-OF: R-04532-11527 The LIKE operator is case sensitive by 942f5d3df40Sdan# default for unicode characters that are beyond the ASCII range. 943f5d3df40Sdan# 944f5d3df40Sdan# EVIDENCE-OF: R-44381-11669 the expression 945f5d3df40Sdan# 'a' LIKE 'A' is TRUE but 946f5d3df40Sdan# 'æ' LIKE 'Æ' is FALSE. 947f5d3df40Sdan# 9486bd2c735Sdan# The restriction to ASCII characters does not apply if the ICU 9496bd2c735Sdan# library is compiled in. When ICU is enabled SQLite does not act 9506bd2c735Sdan# as it does "by default". 9516bd2c735Sdan# 952f5d3df40Sdando_execsql_test e_expr-14.5.1 { SELECT 'A' LIKE 'a' } 1 9536bd2c735Sdanifcapable !icu { 954f5d3df40Sdan do_execsql_test e_expr-14.5.2 "SELECT '\u00c6' LIKE '\u00e6'" 0 9556bd2c735Sdan} 956f5d3df40Sdan 957f5d3df40Sdan# EVIDENCE-OF: R-56683-13731 If the optional ESCAPE clause is present, 958f5d3df40Sdan# then the expression following the ESCAPE keyword must evaluate to a 959f5d3df40Sdan# string consisting of a single character. 960f5d3df40Sdan# 961f5d3df40Sdando_catchsql_test e_expr-14.6.1 { 962f5d3df40Sdan SELECT 'A' LIKE 'a' ESCAPE '12' 963f5d3df40Sdan} {1 {ESCAPE expression must be a single character}} 964f5d3df40Sdando_catchsql_test e_expr-14.6.2 { 965f5d3df40Sdan SELECT 'A' LIKE 'a' ESCAPE '' 966f5d3df40Sdan} {1 {ESCAPE expression must be a single character}} 967f5d3df40Sdando_catchsql_test e_expr-14.6.3 { SELECT 'A' LIKE 'a' ESCAPE 'x' } {0 1} 968f5d3df40Sdando_catchsql_test e_expr-14.6.4 "SELECT 'A' LIKE 'a' ESCAPE '\u00e6'" {0 1} 969f5d3df40Sdan 970f5d3df40Sdan# EVIDENCE-OF: R-02045-23762 This character may be used in the LIKE 971f5d3df40Sdan# pattern to include literal percent or underscore characters. 972f5d3df40Sdan# 973f5d3df40Sdan# EVIDENCE-OF: R-13345-31830 The escape character followed by a percent 974f5d3df40Sdan# symbol (%), underscore (_), or a second instance of the escape 975f5d3df40Sdan# character itself matches a literal percent symbol, underscore, or a 976f5d3df40Sdan# single escape character, respectively. 977f5d3df40Sdan# 978f5d3df40Sdando_execsql_test e_expr-14.7.1 { SELECT 'abc%' LIKE 'abcX%' ESCAPE 'X' } 1 979f5d3df40Sdando_execsql_test e_expr-14.7.2 { SELECT 'abc5' LIKE 'abcX%' ESCAPE 'X' } 0 980f5d3df40Sdando_execsql_test e_expr-14.7.3 { SELECT 'abc' LIKE 'abcX%' ESCAPE 'X' } 0 981f5d3df40Sdando_execsql_test e_expr-14.7.4 { SELECT 'abcX%' LIKE 'abcX%' ESCAPE 'X' } 0 982f5d3df40Sdando_execsql_test e_expr-14.7.5 { SELECT 'abc%%' LIKE 'abcX%' ESCAPE 'X' } 0 983f5d3df40Sdan 984f5d3df40Sdando_execsql_test e_expr-14.7.6 { SELECT 'abc_' LIKE 'abcX_' ESCAPE 'X' } 1 985f5d3df40Sdando_execsql_test e_expr-14.7.7 { SELECT 'abc5' LIKE 'abcX_' ESCAPE 'X' } 0 986f5d3df40Sdando_execsql_test e_expr-14.7.8 { SELECT 'abc' LIKE 'abcX_' ESCAPE 'X' } 0 987f5d3df40Sdando_execsql_test e_expr-14.7.9 { SELECT 'abcX_' LIKE 'abcX_' ESCAPE 'X' } 0 988f5d3df40Sdando_execsql_test e_expr-14.7.10 { SELECT 'abc__' LIKE 'abcX_' ESCAPE 'X' } 0 989f5d3df40Sdan 990f5d3df40Sdando_execsql_test e_expr-14.7.11 { SELECT 'abcX' LIKE 'abcXX' ESCAPE 'X' } 1 991f5d3df40Sdando_execsql_test e_expr-14.7.12 { SELECT 'abc5' LIKE 'abcXX' ESCAPE 'X' } 0 992f5d3df40Sdando_execsql_test e_expr-14.7.13 { SELECT 'abc' LIKE 'abcXX' ESCAPE 'X' } 0 993f5d3df40Sdando_execsql_test e_expr-14.7.14 { SELECT 'abcXX' LIKE 'abcXX' ESCAPE 'X' } 0 994f5d3df40Sdan 995f5d3df40Sdan# EVIDENCE-OF: R-51359-17496 The infix LIKE operator is implemented by 996f5d3df40Sdan# calling the application-defined SQL functions like(Y,X) or like(Y,X,Z). 997f5d3df40Sdan# 998f5d3df40Sdanproc likefunc {args} { 999f5d3df40Sdan eval lappend ::likeargs $args 1000f5d3df40Sdan return 1 1001f5d3df40Sdan} 10026bd2c735Sdandb func like -argcount 2 likefunc 10036bd2c735Sdandb func like -argcount 3 likefunc 1004f5d3df40Sdanset ::likeargs [list] 1005f5d3df40Sdando_execsql_test e_expr-15.1.1 { SELECT 'abc' LIKE 'def' } 1 1006f5d3df40Sdando_test e_expr-15.1.2 { set likeargs } {def abc} 1007f5d3df40Sdanset ::likeargs [list] 1008f5d3df40Sdando_execsql_test e_expr-15.1.3 { SELECT 'abc' LIKE 'def' ESCAPE 'X' } 1 1009f5d3df40Sdando_test e_expr-15.1.4 { set likeargs } {def abc X} 1010f5d3df40Sdandb close 1011f5d3df40Sdansqlite3 db test.db 1012f5d3df40Sdan 1013f5d3df40Sdan# EVIDENCE-OF: R-22868-25880 The LIKE operator can be made case 1014f5d3df40Sdan# sensitive using the case_sensitive_like pragma. 1015f5d3df40Sdan# 1016f5d3df40Sdando_execsql_test e_expr-16.1.1 { SELECT 'abcxyz' LIKE 'ABC%' } 1 1017*ea5c040fSdrhdo_execsql_test e_expr-16.1.1b { SELECT 'abc%xyz' LIKE 'ABC\%x%' ESCAPE '\' } 1 1018f5d3df40Sdando_execsql_test e_expr-16.1.2 { PRAGMA case_sensitive_like = 1 } {} 1019f5d3df40Sdando_execsql_test e_expr-16.1.3 { SELECT 'abcxyz' LIKE 'ABC%' } 0 1020*ea5c040fSdrhdo_execsql_test e_expr-16.1.3b { SELECT 'abc%xyz' LIKE 'ABC\%X%' ESCAPE '\' } 0 1021f5d3df40Sdando_execsql_test e_expr-16.1.4 { SELECT 'ABCxyz' LIKE 'ABC%' } 1 1022*ea5c040fSdrhdo_execsql_test e_expr-16.1.4b { SELECT 'ABC%xyz' LIKE 'ABC\%x%' ESCAPE '\' } 1 1023f5d3df40Sdando_execsql_test e_expr-16.1.5 { PRAGMA case_sensitive_like = 0 } {} 1024f5d3df40Sdando_execsql_test e_expr-16.1.6 { SELECT 'abcxyz' LIKE 'ABC%' } 1 1025*ea5c040fSdrhdo_execsql_test e_expr-16.1.6b { SELECT 'abc%xyz' LIKE 'ABC\%X%' ESCAPE '\' } 1 1026f5d3df40Sdando_execsql_test e_expr-16.1.7 { SELECT 'ABCxyz' LIKE 'ABC%' } 1 1027*ea5c040fSdrhdo_execsql_test e_expr-16.1.7b { SELECT 'ABC%xyz' LIKE 'ABC\%X%' ESCAPE '\' } 1 1028f5d3df40Sdan 1029f5d3df40Sdan# EVIDENCE-OF: R-52087-12043 The GLOB operator is similar to LIKE but 1030f5d3df40Sdan# uses the Unix file globbing syntax for its wildcards. 1031f5d3df40Sdan# 1032f5d3df40Sdan# EVIDENCE-OF: R-09813-17279 Also, GLOB is case sensitive, unlike LIKE. 1033f5d3df40Sdan# 1034f5d3df40Sdando_execsql_test e_expr-17.1.1 { SELECT 'abcxyz' GLOB 'abc%' } 0 1035f5d3df40Sdando_execsql_test e_expr-17.1.2 { SELECT 'abcxyz' GLOB 'abc*' } 1 1036f5d3df40Sdando_execsql_test e_expr-17.1.3 { SELECT 'abcxyz' GLOB 'abc___' } 0 1037f5d3df40Sdando_execsql_test e_expr-17.1.4 { SELECT 'abcxyz' GLOB 'abc???' } 1 1038f5d3df40Sdan 1039f5d3df40Sdando_execsql_test e_expr-17.1.5 { SELECT 'abcxyz' GLOB 'abc*' } 1 1040f5d3df40Sdando_execsql_test e_expr-17.1.6 { SELECT 'ABCxyz' GLOB 'abc*' } 0 1041f5d3df40Sdando_execsql_test e_expr-17.1.7 { SELECT 'abcxyz' GLOB 'ABC*' } 0 1042f5d3df40Sdan 1043f5d3df40Sdan# EVIDENCE-OF: R-39616-20555 Both GLOB and LIKE may be preceded by the 1044f5d3df40Sdan# NOT keyword to invert the sense of the test. 1045f5d3df40Sdan# 1046f5d3df40Sdando_execsql_test e_expr-17.2.1 { SELECT 'abcxyz' NOT GLOB 'ABC*' } 1 1047f5d3df40Sdando_execsql_test e_expr-17.2.2 { SELECT 'abcxyz' NOT GLOB 'abc*' } 0 1048f5d3df40Sdando_execsql_test e_expr-17.2.3 { SELECT 'abcxyz' NOT LIKE 'ABC%' } 0 1049f5d3df40Sdando_execsql_test e_expr-17.2.4 { SELECT 'abcxyz' NOT LIKE 'abc%' } 0 1050f5d3df40Sdando_execsql_test e_expr-17.2.5 { SELECT 'abdxyz' NOT LIKE 'abc%' } 1 1051f5d3df40Sdan 1052f5d3df40Sdandb nullvalue null 1053f5d3df40Sdando_execsql_test e_expr-17.2.6 { SELECT 'abcxyz' NOT GLOB NULL } null 1054f5d3df40Sdando_execsql_test e_expr-17.2.7 { SELECT 'abcxyz' NOT LIKE NULL } null 1055f5d3df40Sdando_execsql_test e_expr-17.2.8 { SELECT NULL NOT GLOB 'abc*' } null 1056f5d3df40Sdando_execsql_test e_expr-17.2.9 { SELECT NULL NOT LIKE 'ABC%' } null 1057f5d3df40Sdandb nullvalue {} 1058f5d3df40Sdan 1059f5d3df40Sdan# EVIDENCE-OF: R-39414-35489 The infix GLOB operator is implemented by 1060f5d3df40Sdan# calling the function glob(Y,X) and can be modified by overriding that 1061f5d3df40Sdan# function. 1062f5d3df40Sdanproc globfunc {args} { 1063f5d3df40Sdan eval lappend ::globargs $args 1064f5d3df40Sdan return 1 1065f5d3df40Sdan} 1066f5d3df40Sdandb func glob -argcount 2 globfunc 1067f5d3df40Sdanset ::globargs [list] 1068f5d3df40Sdando_execsql_test e_expr-17.3.1 { SELECT 'abc' GLOB 'def' } 1 1069f5d3df40Sdando_test e_expr-17.3.2 { set globargs } {def abc} 1070f5d3df40Sdanset ::globargs [list] 1071f5d3df40Sdando_execsql_test e_expr-17.3.3 { SELECT 'X' NOT GLOB 'Y' } 0 1072f5d3df40Sdando_test e_expr-17.3.4 { set globargs } {Y X} 1073f5d3df40Sdansqlite3 db test.db 1074f5d3df40Sdan 1075f5d3df40Sdan# EVIDENCE-OF: R-41650-20872 No regexp() user function is defined by 1076f5d3df40Sdan# default and so use of the REGEXP operator will normally result in an 1077f5d3df40Sdan# error message. 1078f5d3df40Sdan# 10796bd2c735Sdan# There is a regexp function if ICU is enabled though. 10806bd2c735Sdan# 10816bd2c735Sdanifcapable !icu { 1082f5d3df40Sdan do_catchsql_test e_expr-18.1.1 { 1083f5d3df40Sdan SELECT regexp('abc', 'def') 1084f5d3df40Sdan } {1 {no such function: regexp}} 1085f5d3df40Sdan do_catchsql_test e_expr-18.1.2 { 1086f5d3df40Sdan SELECT 'abc' REGEXP 'def' 1087f5d3df40Sdan } {1 {no such function: REGEXP}} 10886bd2c735Sdan} 1089f5d3df40Sdan 1090f5d3df40Sdan# EVIDENCE-OF: R-33693-50180 The REGEXP operator is a special syntax for 1091f5d3df40Sdan# the regexp() user function. 1092f5d3df40Sdan# 1093f37139f6Sdrh# EVIDENCE-OF: R-65524-61849 If an application-defined SQL function 1094f37139f6Sdrh# named "regexp" is added at run-time, then the "X REGEXP Y" operator 1095f37139f6Sdrh# will be implemented as a call to "regexp(Y,X)". 1096f5d3df40Sdan# 1097f5d3df40Sdanproc regexpfunc {args} { 1098f5d3df40Sdan eval lappend ::regexpargs $args 1099f5d3df40Sdan return 1 1100f5d3df40Sdan} 1101f5d3df40Sdandb func regexp -argcount 2 regexpfunc 1102f5d3df40Sdanset ::regexpargs [list] 1103f5d3df40Sdando_execsql_test e_expr-18.2.1 { SELECT 'abc' REGEXP 'def' } 1 1104f5d3df40Sdando_test e_expr-18.2.2 { set regexpargs } {def abc} 1105f5d3df40Sdanset ::regexpargs [list] 1106f5d3df40Sdando_execsql_test e_expr-18.2.3 { SELECT 'X' NOT REGEXP 'Y' } 0 1107f5d3df40Sdando_test e_expr-18.2.4 { set regexpargs } {Y X} 1108f5d3df40Sdansqlite3 db test.db 1109f5d3df40Sdan 1110f5d3df40Sdan# EVIDENCE-OF: R-42037-37826 The default match() function implementation 1111f5d3df40Sdan# raises an exception and is not really useful for anything. 1112f5d3df40Sdan# 1113f5d3df40Sdando_catchsql_test e_expr-19.1.1 { 1114f5d3df40Sdan SELECT 'abc' MATCH 'def' 1115f5d3df40Sdan} {1 {unable to use function MATCH in the requested context}} 1116f5d3df40Sdando_catchsql_test e_expr-19.1.2 { 1117f5d3df40Sdan SELECT match('abc', 'def') 1118f5d3df40Sdan} {1 {unable to use function MATCH in the requested context}} 1119f5d3df40Sdan 1120f5d3df40Sdan# EVIDENCE-OF: R-37916-47407 The MATCH operator is a special syntax for 1121f5d3df40Sdan# the match() application-defined function. 1122f5d3df40Sdan# 1123f5d3df40Sdan# EVIDENCE-OF: R-06021-09373 But extensions can override the match() 1124f5d3df40Sdan# function with more helpful logic. 1125f5d3df40Sdan# 1126f5d3df40Sdanproc matchfunc {args} { 1127f5d3df40Sdan eval lappend ::matchargs $args 1128f5d3df40Sdan return 1 1129f5d3df40Sdan} 1130f5d3df40Sdandb func match -argcount 2 matchfunc 1131f5d3df40Sdanset ::matchargs [list] 1132f5d3df40Sdando_execsql_test e_expr-19.2.1 { SELECT 'abc' MATCH 'def' } 1 1133f5d3df40Sdando_test e_expr-19.2.2 { set matchargs } {def abc} 1134f5d3df40Sdanset ::matchargs [list] 1135f5d3df40Sdando_execsql_test e_expr-19.2.3 { SELECT 'X' NOT MATCH 'Y' } 0 1136f5d3df40Sdando_test e_expr-19.2.4 { set matchargs } {Y X} 1137f5d3df40Sdansqlite3 db test.db 1138f5d3df40Sdan 1139eb385b40Sdan#------------------------------------------------------------------------- 1140eb385b40Sdan# Test cases for the testable statements related to the CASE expression. 1141eb385b40Sdan# 1142eb385b40Sdan# EVIDENCE-OF: R-15199-61389 There are two basic forms of the CASE 1143eb385b40Sdan# expression: those with a base expression and those without. 1144eb385b40Sdan# 1145eb385b40Sdando_execsql_test e_expr-20.1 { 1146eb385b40Sdan SELECT CASE WHEN 1 THEN 'true' WHEN 0 THEN 'false' ELSE 'else' END; 1147eb385b40Sdan} {true} 1148eb385b40Sdando_execsql_test e_expr-20.2 { 1149eb385b40Sdan SELECT CASE 0 WHEN 1 THEN 'true' WHEN 0 THEN 'false' ELSE 'else' END; 1150eb385b40Sdan} {false} 1151eb385b40Sdan 1152eb385b40Sdanproc var {nm} { 1153eb385b40Sdan lappend ::varlist $nm 1154eb385b40Sdan return [set "::$nm"] 1155eb385b40Sdan} 1156eb385b40Sdandb func var var 1157eb385b40Sdan 1158eb385b40Sdan# EVIDENCE-OF: R-30638-59954 In a CASE without a base expression, each 1159eb385b40Sdan# WHEN expression is evaluated and the result treated as a boolean, 1160eb385b40Sdan# starting with the leftmost and continuing to the right. 1161eb385b40Sdan# 1162eb385b40Sdanforeach {a b c} {0 0 0} break 1163eb385b40Sdanset varlist [list] 1164eb385b40Sdando_execsql_test e_expr-21.1.1 { 1165eb385b40Sdan SELECT CASE WHEN var('a') THEN 'A' 1166eb385b40Sdan WHEN var('b') THEN 'B' 1167eb385b40Sdan WHEN var('c') THEN 'C' END 1168eb385b40Sdan} {{}} 1169eb385b40Sdando_test e_expr-21.1.2 { set varlist } {a b c} 1170eb385b40Sdanset varlist [list] 1171eb385b40Sdando_execsql_test e_expr-21.1.3 { 1172eb385b40Sdan SELECT CASE WHEN var('c') THEN 'C' 1173eb385b40Sdan WHEN var('b') THEN 'B' 1174eb385b40Sdan WHEN var('a') THEN 'A' 1175eb385b40Sdan ELSE 'no result' 1176eb385b40Sdan END 1177eb385b40Sdan} {{no result}} 1178eb385b40Sdando_test e_expr-21.1.4 { set varlist } {c b a} 1179eb385b40Sdan 1180eb385b40Sdan# EVIDENCE-OF: R-39009-25596 The result of the CASE expression is the 1181eb385b40Sdan# evaluation of the THEN expression that corresponds to the first WHEN 1182eb385b40Sdan# expression that evaluates to true. 1183eb385b40Sdan# 1184eb385b40Sdanforeach {a b c} {0 1 0} break 1185eb385b40Sdando_execsql_test e_expr-21.2.1 { 1186eb385b40Sdan SELECT CASE WHEN var('a') THEN 'A' 1187eb385b40Sdan WHEN var('b') THEN 'B' 1188eb385b40Sdan WHEN var('c') THEN 'C' 1189eb385b40Sdan ELSE 'no result' 1190eb385b40Sdan END 1191eb385b40Sdan} {B} 1192eb385b40Sdanforeach {a b c} {0 1 1} break 1193eb385b40Sdando_execsql_test e_expr-21.2.2 { 1194eb385b40Sdan SELECT CASE WHEN var('a') THEN 'A' 1195eb385b40Sdan WHEN var('b') THEN 'B' 1196eb385b40Sdan WHEN var('c') THEN 'C' 1197eb385b40Sdan ELSE 'no result' 1198eb385b40Sdan END 1199eb385b40Sdan} {B} 1200eb385b40Sdanforeach {a b c} {0 0 1} break 1201eb385b40Sdando_execsql_test e_expr-21.2.3 { 1202eb385b40Sdan SELECT CASE WHEN var('a') THEN 'A' 1203eb385b40Sdan WHEN var('b') THEN 'B' 1204eb385b40Sdan WHEN var('c') THEN 'C' 1205eb385b40Sdan ELSE 'no result' 1206eb385b40Sdan END 1207eb385b40Sdan} {C} 1208eb385b40Sdan 1209eb385b40Sdan# EVIDENCE-OF: R-24227-04807 Or, if none of the WHEN expressions 1210eb385b40Sdan# evaluate to true, the result of evaluating the ELSE expression, if 1211eb385b40Sdan# any. 1212eb385b40Sdan# 1213eb385b40Sdanforeach {a b c} {0 0 0} break 1214eb385b40Sdando_execsql_test e_expr-21.3.1 { 1215eb385b40Sdan SELECT CASE WHEN var('a') THEN 'A' 1216eb385b40Sdan WHEN var('b') THEN 'B' 1217eb385b40Sdan WHEN var('c') THEN 'C' 1218eb385b40Sdan ELSE 'no result' 1219eb385b40Sdan END 1220eb385b40Sdan} {{no result}} 1221eb385b40Sdan 1222eb385b40Sdan# EVIDENCE-OF: R-14168-07579 If there is no ELSE expression and none of 1223eb385b40Sdan# the WHEN expressions are true, then the overall result is NULL. 1224eb385b40Sdan# 1225eb385b40Sdandb nullvalue null 1226eb385b40Sdando_execsql_test e_expr-21.3.2 { 1227eb385b40Sdan SELECT CASE WHEN var('a') THEN 'A' 1228eb385b40Sdan WHEN var('b') THEN 'B' 1229eb385b40Sdan WHEN var('c') THEN 'C' 1230eb385b40Sdan END 1231eb385b40Sdan} {null} 1232eb385b40Sdandb nullvalue {} 1233eb385b40Sdan 1234eb385b40Sdan# EVIDENCE-OF: R-13943-13592 A NULL result is considered untrue when 1235eb385b40Sdan# evaluating WHEN terms. 1236eb385b40Sdan# 1237eb385b40Sdando_execsql_test e_expr-21.4.1 { 1238eb385b40Sdan SELECT CASE WHEN NULL THEN 'A' WHEN 1 THEN 'B' END 1239eb385b40Sdan} {B} 1240eb385b40Sdando_execsql_test e_expr-21.4.2 { 1241eb385b40Sdan SELECT CASE WHEN 0 THEN 'A' WHEN NULL THEN 'B' ELSE 'C' END 1242eb385b40Sdan} {C} 1243eb385b40Sdan 1244eb385b40Sdan# EVIDENCE-OF: R-38620-19499 In a CASE with a base expression, the base 1245eb385b40Sdan# expression is evaluated just once and the result is compared against 1246eb385b40Sdan# the evaluation of each WHEN expression from left to right. 1247eb385b40Sdan# 1248eb385b40Sdan# Note: This test case tests the "evaluated just once" part of the above 1249eb385b40Sdan# statement. Tests associated with the next two statements test that the 1250eb385b40Sdan# comparisons take place. 1251eb385b40Sdan# 1252eb385b40Sdanforeach {a b c} [list [expr 3] [expr 4] [expr 5]] break 1253eb385b40Sdanset ::varlist [list] 1254eb385b40Sdando_execsql_test e_expr-22.1.1 { 1255eb385b40Sdan SELECT CASE var('a') WHEN 1 THEN 'A' WHEN 2 THEN 'B' WHEN 3 THEN 'C' END 1256eb385b40Sdan} {C} 1257eb385b40Sdando_test e_expr-22.1.2 { set ::varlist } {a} 1258eb385b40Sdan 1259eb385b40Sdan# EVIDENCE-OF: R-07667-49537 The result of the CASE expression is the 1260eb385b40Sdan# evaluation of the THEN expression that corresponds to the first WHEN 1261eb385b40Sdan# expression for which the comparison is true. 1262eb385b40Sdan# 1263eb385b40Sdando_execsql_test e_expr-22.2.1 { 1264eb385b40Sdan SELECT CASE 23 WHEN 1 THEN 'A' WHEN 23 THEN 'B' WHEN 23 THEN 'C' END 1265eb385b40Sdan} {B} 1266eb385b40Sdando_execsql_test e_expr-22.2.2 { 1267eb385b40Sdan SELECT CASE 1 WHEN 1 THEN 'A' WHEN 23 THEN 'B' WHEN 23 THEN 'C' END 1268eb385b40Sdan} {A} 1269eb385b40Sdan 1270eb385b40Sdan# EVIDENCE-OF: R-47543-32145 Or, if none of the WHEN expressions 1271eb385b40Sdan# evaluate to a value equal to the base expression, the result of 1272eb385b40Sdan# evaluating the ELSE expression, if any. 1273eb385b40Sdan# 1274eb385b40Sdando_execsql_test e_expr-22.3.1 { 1275eb385b40Sdan SELECT CASE 24 WHEN 1 THEN 'A' WHEN 23 THEN 'B' WHEN 23 THEN 'C' ELSE 'D' END 1276eb385b40Sdan} {D} 1277eb385b40Sdan 1278eb385b40Sdan# EVIDENCE-OF: R-54721-48557 If there is no ELSE expression and none of 1279eb385b40Sdan# the WHEN expressions produce a result equal to the base expression, 1280eb385b40Sdan# the overall result is NULL. 1281eb385b40Sdan# 1282eb385b40Sdando_execsql_test e_expr-22.4.1 { 1283eb385b40Sdan SELECT CASE 24 WHEN 1 THEN 'A' WHEN 23 THEN 'B' WHEN 23 THEN 'C' END 1284eb385b40Sdan} {{}} 1285eb385b40Sdandb nullvalue null 1286eb385b40Sdando_execsql_test e_expr-22.4.2 { 1287eb385b40Sdan SELECT CASE 24 WHEN 1 THEN 'A' WHEN 23 THEN 'B' WHEN 23 THEN 'C' END 1288eb385b40Sdan} {null} 1289eb385b40Sdandb nullvalue {} 1290eb385b40Sdan 1291eb385b40Sdan# EVIDENCE-OF: R-11479-62774 When comparing a base expression against a 1292eb385b40Sdan# WHEN expression, the same collating sequence, affinity, and 1293eb385b40Sdan# NULL-handling rules apply as if the base expression and WHEN 1294eb385b40Sdan# expression are respectively the left- and right-hand operands of an = 1295eb385b40Sdan# operator. 1296eb385b40Sdan# 1297eb385b40Sdanproc rev {str} { 1298eb385b40Sdan set ret "" 1299eb385b40Sdan set chars [split $str] 1300eb385b40Sdan for {set i [expr [llength $chars]-1]} {$i>=0} {incr i -1} { 1301eb385b40Sdan append ret [lindex $chars $i] 1302eb385b40Sdan } 1303eb385b40Sdan set ret 1304eb385b40Sdan} 1305eb385b40Sdanproc reverse {lhs rhs} { 1306c0c3c262Sdan string compare [rev $lhs] [rev $rhs] 1307eb385b40Sdan} 1308eb385b40Sdandb collate reverse reverse 1309eb385b40Sdando_execsql_test e_expr-23.1.1 { 1310eb385b40Sdan CREATE TABLE t1( 1311eb385b40Sdan a TEXT COLLATE NOCASE, 1312eb385b40Sdan b COLLATE REVERSE, 1313eb385b40Sdan c INTEGER, 1314eb385b40Sdan d BLOB 1315eb385b40Sdan ); 1316eb385b40Sdan INSERT INTO t1 VALUES('abc', 'cba', 55, 34.5); 1317eb385b40Sdan} {} 1318eb385b40Sdando_execsql_test e_expr-23.1.2 { 1319eb385b40Sdan SELECT CASE a WHEN 'xyz' THEN 'A' WHEN 'AbC' THEN 'B' END FROM t1 1320eb385b40Sdan} {B} 1321eb385b40Sdando_execsql_test e_expr-23.1.3 { 1322eb385b40Sdan SELECT CASE 'AbC' WHEN 'abc' THEN 'A' WHEN a THEN 'B' END FROM t1 1323eb385b40Sdan} {B} 1324eb385b40Sdando_execsql_test e_expr-23.1.4 { 1325eb385b40Sdan SELECT CASE a WHEN b THEN 'A' ELSE 'B' END FROM t1 1326eb385b40Sdan} {B} 1327eb385b40Sdando_execsql_test e_expr-23.1.5 { 1328eb385b40Sdan SELECT CASE b WHEN a THEN 'A' ELSE 'B' END FROM t1 1329c0c3c262Sdan} {B} 1330eb385b40Sdando_execsql_test e_expr-23.1.6 { 1331eb385b40Sdan SELECT CASE 55 WHEN '55' THEN 'A' ELSE 'B' END 1332eb385b40Sdan} {B} 1333eb385b40Sdando_execsql_test e_expr-23.1.7 { 1334eb385b40Sdan SELECT CASE c WHEN '55' THEN 'A' ELSE 'B' END FROM t1 1335eb385b40Sdan} {A} 1336eb385b40Sdando_execsql_test e_expr-23.1.8 { 1337eb385b40Sdan SELECT CASE '34.5' WHEN d THEN 'A' ELSE 'B' END FROM t1 1338eb385b40Sdan} {B} 1339eb385b40Sdando_execsql_test e_expr-23.1.9 { 1340eb385b40Sdan SELECT CASE NULL WHEN NULL THEN 'A' ELSE 'B' END 1341eb385b40Sdan} {B} 1342eb385b40Sdan 1343eb385b40Sdan# EVIDENCE-OF: R-37304-39405 If the base expression is NULL then the 1344eb385b40Sdan# result of the CASE is always the result of evaluating the ELSE 1345eb385b40Sdan# expression if it exists, or NULL if it does not. 1346eb385b40Sdan# 1347eb385b40Sdando_execsql_test e_expr-24.1.1 { 1348eb385b40Sdan SELECT CASE NULL WHEN 'abc' THEN 'A' WHEN 'def' THEN 'B' END; 1349eb385b40Sdan} {{}} 1350eb385b40Sdando_execsql_test e_expr-24.1.2 { 1351eb385b40Sdan SELECT CASE NULL WHEN 'abc' THEN 'A' WHEN 'def' THEN 'B' ELSE 'C' END; 1352eb385b40Sdan} {C} 1353eb385b40Sdan 1354eb385b40Sdan# EVIDENCE-OF: R-56280-17369 Both forms of the CASE expression use lazy, 1355eb385b40Sdan# or short-circuit, evaluation. 1356eb385b40Sdan# 1357eb385b40Sdanset varlist [list] 1358eb385b40Sdanforeach {a b c} {0 1 0} break 1359eb385b40Sdando_execsql_test e_expr-25.1.1 { 1360eb385b40Sdan SELECT CASE WHEN var('a') THEN 'A' 1361eb385b40Sdan WHEN var('b') THEN 'B' 1362eb385b40Sdan WHEN var('c') THEN 'C' 1363eb385b40Sdan END 1364eb385b40Sdan} {B} 1365eb385b40Sdando_test e_expr-25.1.2 { set ::varlist } {a b} 1366eb385b40Sdanset varlist [list] 1367eb385b40Sdando_execsql_test e_expr-25.1.3 { 1368eb385b40Sdan SELECT CASE '0' WHEN var('a') THEN 'A' 1369eb385b40Sdan WHEN var('b') THEN 'B' 1370eb385b40Sdan WHEN var('c') THEN 'C' 1371eb385b40Sdan END 1372eb385b40Sdan} {A} 1373eb385b40Sdando_test e_expr-25.1.4 { set ::varlist } {a} 1374eb385b40Sdan 1375eb385b40Sdan# EVIDENCE-OF: R-34773-62253 The only difference between the following 1376eb385b40Sdan# two CASE expressions is that the x expression is evaluated exactly 1377eb385b40Sdan# once in the first example but might be evaluated multiple times in the 1378eb385b40Sdan# second: CASE x WHEN w1 THEN r1 WHEN w2 THEN r2 ELSE r3 END CASE WHEN 1379eb385b40Sdan# x=w1 THEN r1 WHEN x=w2 THEN r2 ELSE r3 END 1380eb385b40Sdan# 1381eb385b40Sdanproc ceval {x} { 1382eb385b40Sdan incr ::evalcount 1383eb385b40Sdan return $x 1384eb385b40Sdan} 1385eb385b40Sdandb func ceval ceval 1386eb385b40Sdanset ::evalcount 0 1387eb385b40Sdan 1388eb385b40Sdando_execsql_test e_expr-26.1.1 { 1389eb385b40Sdan CREATE TABLE t2(x, w1, r1, w2, r2, r3); 1390eb385b40Sdan INSERT INTO t2 VALUES(1, 1, 'R1', 2, 'R2', 'R3'); 1391eb385b40Sdan INSERT INTO t2 VALUES(2, 1, 'R1', 2, 'R2', 'R3'); 1392eb385b40Sdan INSERT INTO t2 VALUES(3, 1, 'R1', 2, 'R2', 'R3'); 1393eb385b40Sdan} {} 1394eb385b40Sdando_execsql_test e_expr-26.1.2 { 1395eb385b40Sdan SELECT CASE x WHEN w1 THEN r1 WHEN w2 THEN r2 ELSE r3 END FROM t2 1396eb385b40Sdan} {R1 R2 R3} 1397eb385b40Sdando_execsql_test e_expr-26.1.3 { 1398eb385b40Sdan SELECT CASE WHEN x=w1 THEN r1 WHEN x=w2 THEN r2 ELSE r3 END FROM t2 1399eb385b40Sdan} {R1 R2 R3} 1400eb385b40Sdan 1401eb385b40Sdando_execsql_test e_expr-26.1.4 { 1402eb385b40Sdan SELECT CASE ceval(x) WHEN w1 THEN r1 WHEN w2 THEN r2 ELSE r3 END FROM t2 1403eb385b40Sdan} {R1 R2 R3} 1404eb385b40Sdando_test e_expr-26.1.5 { set ::evalcount } {3} 1405eb385b40Sdanset ::evalcount 0 1406eb385b40Sdando_execsql_test e_expr-26.1.6 { 1407eb385b40Sdan SELECT CASE 1408eb385b40Sdan WHEN ceval(x)=w1 THEN r1 1409eb385b40Sdan WHEN ceval(x)=w2 THEN r2 1410eb385b40Sdan ELSE r3 END 1411eb385b40Sdan FROM t2 1412eb385b40Sdan} {R1 R2 R3} 1413eb385b40Sdando_test e_expr-26.1.6 { set ::evalcount } {5} 1414994e9403Sdan 141551f3a505Sdan 141651f3a505Sdan#------------------------------------------------------------------------- 141751f3a505Sdan# Test statements related to CAST expressions. 141851f3a505Sdan# 14199338642cSdrh# EVIDENCE-OF: R-20854-17109 A CAST conversion is similar to the 14209338642cSdrh# conversion that takes place when a column affinity is applied to a 14219338642cSdrh# value except that with the CAST operator the conversion always takes 14229338642cSdrh# place even if the conversion lossy and irreversible, whereas column 14239338642cSdrh# affinity only changes the data type of a value if the change is 14249338642cSdrh# lossless and reversible. 142551f3a505Sdan# 142651f3a505Sdando_execsql_test e_expr-27.1.1 { 142751f3a505Sdan CREATE TABLE t3(a TEXT, b REAL, c INTEGER); 142851f3a505Sdan INSERT INTO t3 VALUES(X'555655', '1.23abc', 4.5); 142951f3a505Sdan SELECT typeof(a), a, typeof(b), b, typeof(c), c FROM t3; 143051f3a505Sdan} {blob UVU text 1.23abc real 4.5} 143151f3a505Sdando_execsql_test e_expr-27.1.2 { 143251f3a505Sdan SELECT 143351f3a505Sdan typeof(CAST(X'555655' as TEXT)), CAST(X'555655' as TEXT), 143451f3a505Sdan typeof(CAST('1.23abc' as REAL)), CAST('1.23abc' as REAL), 143551f3a505Sdan typeof(CAST(4.5 as INTEGER)), CAST(4.5 as INTEGER) 143651f3a505Sdan} {text UVU real 1.23 integer 4} 143751f3a505Sdan 1438b3366b99Sdrh# EVIDENCE-OF: R-32434-09092 If the value of expr is NULL, then the 1439b3366b99Sdrh# result of the CAST expression is also NULL. 144051f3a505Sdan# 144151f3a505Sdando_expr_test e_expr-27.2.1 { CAST(NULL AS integer) } null {} 144251f3a505Sdando_expr_test e_expr-27.2.2 { CAST(NULL AS text) } null {} 144351f3a505Sdando_expr_test e_expr-27.2.3 { CAST(NULL AS blob) } null {} 144451f3a505Sdando_expr_test e_expr-27.2.4 { CAST(NULL AS number) } null {} 144551f3a505Sdan 1446e74cc5c9Sdrh# EVIDENCE-OF: R-29283-15561 Otherwise, the storage class of the result 1447e74cc5c9Sdrh# is determined by applying the rules for determining column affinity to 1448e74cc5c9Sdrh# the type-name. 1449e74cc5c9Sdrh# 1450e74cc5c9Sdrh# The R-29283-15561 requirement above is demonstrated by all of the 1451e74cc5c9Sdrh# subsequent e_expr-26 tests. 1452e74cc5c9Sdrh# 1453b3366b99Sdrh# EVIDENCE-OF: R-43522-35548 Casting a value to a type-name with no 1454b3366b99Sdrh# affinity causes the value to be converted into a BLOB. 145551f3a505Sdan# 145651f3a505Sdando_expr_test e_expr-27.3.1 { CAST('abc' AS blob) } blob abc 145751f3a505Sdando_expr_test e_expr-27.3.2 { CAST('def' AS shobblob_x) } blob def 145851f3a505Sdando_expr_test e_expr-27.3.3 { CAST('ghi' AS abbLOb10) } blob ghi 145951f3a505Sdan 146051f3a505Sdan# EVIDENCE-OF: R-22956-37754 Casting to a BLOB consists of first casting 146151f3a505Sdan# the value to TEXT in the encoding of the database connection, then 146251f3a505Sdan# interpreting the resulting byte sequence as a BLOB instead of as TEXT. 146351f3a505Sdan# 146451f3a505Sdando_qexpr_test e_expr-27.4.1 { CAST('ghi' AS blob) } X'676869' 146551f3a505Sdando_qexpr_test e_expr-27.4.2 { CAST(456 AS blob) } X'343536' 146651f3a505Sdando_qexpr_test e_expr-27.4.3 { CAST(1.78 AS blob) } X'312E3738' 146751f3a505Sdanrename db db2 146851f3a505Sdansqlite3 db :memory: 14696faa5fdfSshanehifcapable {utf16} { 147051f3a505Sdandb eval { PRAGMA encoding = 'utf-16le' } 147151f3a505Sdando_qexpr_test e_expr-27.4.4 { CAST('ghi' AS blob) } X'670068006900' 147251f3a505Sdando_qexpr_test e_expr-27.4.5 { CAST(456 AS blob) } X'340035003600' 147351f3a505Sdando_qexpr_test e_expr-27.4.6 { CAST(1.78 AS blob) } X'31002E0037003800' 14746faa5fdfSshaneh} 147551f3a505Sdandb close 147651f3a505Sdansqlite3 db :memory: 147751f3a505Sdandb eval { PRAGMA encoding = 'utf-16be' } 14786faa5fdfSshanehifcapable {utf16} { 147951f3a505Sdando_qexpr_test e_expr-27.4.7 { CAST('ghi' AS blob) } X'006700680069' 148051f3a505Sdando_qexpr_test e_expr-27.4.8 { CAST(456 AS blob) } X'003400350036' 148151f3a505Sdando_qexpr_test e_expr-27.4.9 { CAST(1.78 AS blob) } X'0031002E00370038' 14826faa5fdfSshaneh} 148351f3a505Sdandb close 148451f3a505Sdanrename db2 db 148551f3a505Sdan 148651f3a505Sdan# EVIDENCE-OF: R-04207-37981 To cast a BLOB value to TEXT, the sequence 148751f3a505Sdan# of bytes that make up the BLOB is interpreted as text encoded using 148851f3a505Sdan# the database encoding. 148951f3a505Sdan# 149051f3a505Sdando_expr_test e_expr-28.1.1 { CAST (X'676869' AS text) } text ghi 149151f3a505Sdando_expr_test e_expr-28.1.2 { CAST (X'670068006900' AS text) } text g 149251f3a505Sdanrename db db2 149351f3a505Sdansqlite3 db :memory: 149451f3a505Sdandb eval { PRAGMA encoding = 'utf-16le' } 14956faa5fdfSshanehifcapable {utf16} { 149651f3a505Sdando_expr_test e_expr-28.1.3 { CAST (X'676869' AS text) == 'ghi' } integer 0 149751f3a505Sdando_expr_test e_expr-28.1.4 { CAST (X'670068006900' AS text) } text ghi 14986faa5fdfSshaneh} 149951f3a505Sdandb close 150051f3a505Sdanrename db2 db 150151f3a505Sdan 150251f3a505Sdan# EVIDENCE-OF: R-22235-47006 Casting an INTEGER or REAL value into TEXT 150351f3a505Sdan# renders the value as if via sqlite3_snprintf() except that the 150451f3a505Sdan# resulting TEXT uses the encoding of the database connection. 150551f3a505Sdan# 150651f3a505Sdando_expr_test e_expr-28.2.1 { CAST (1 AS text) } text 1 150751f3a505Sdando_expr_test e_expr-28.2.2 { CAST (45 AS text) } text 45 150851f3a505Sdando_expr_test e_expr-28.2.3 { CAST (-45 AS text) } text -45 150951f3a505Sdando_expr_test e_expr-28.2.4 { CAST (8.8 AS text) } text 8.8 151051f3a505Sdando_expr_test e_expr-28.2.5 { CAST (2.3e+5 AS text) } text 230000.0 151151f3a505Sdando_expr_test e_expr-28.2.6 { CAST (-2.3e-5 AS text) } text -2.3e-05 151251f3a505Sdando_expr_test e_expr-28.2.7 { CAST (0.0 AS text) } text 0.0 151351f3a505Sdando_expr_test e_expr-28.2.7 { CAST (0 AS text) } text 0 151451f3a505Sdan 151551f3a505Sdan# EVIDENCE-OF: R-26346-36443 When casting a BLOB value to a REAL, the 151651f3a505Sdan# value is first converted to TEXT. 151751f3a505Sdan# 151851f3a505Sdando_expr_test e_expr-29.1.1 { CAST (X'312E3233' AS REAL) } real 1.23 151951f3a505Sdando_expr_test e_expr-29.1.2 { CAST (X'3233302E30' AS REAL) } real 230.0 152051f3a505Sdando_expr_test e_expr-29.1.3 { CAST (X'2D392E3837' AS REAL) } real -9.87 152151f3a505Sdando_expr_test e_expr-29.1.4 { CAST (X'302E30303031' AS REAL) } real 0.0001 152251f3a505Sdanrename db db2 152351f3a505Sdansqlite3 db :memory: 15246faa5fdfSshanehifcapable {utf16} { 152551f3a505Sdandb eval { PRAGMA encoding = 'utf-16le' } 152648d9e01eSdando_expr_test e_expr-29.1.5 { 152751f3a505Sdan CAST (X'31002E0032003300' AS REAL) } real 1.23 152848d9e01eSdando_expr_test e_expr-29.1.6 { 152951f3a505Sdan CAST (X'3200330030002E003000' AS REAL) } real 230.0 153048d9e01eSdando_expr_test e_expr-29.1.7 { 153151f3a505Sdan CAST (X'2D0039002E0038003700' AS REAL) } real -9.87 153248d9e01eSdando_expr_test e_expr-29.1.8 { 153351f3a505Sdan CAST (X'30002E003000300030003100' AS REAL) } real 0.0001 15346faa5fdfSshaneh} 153551f3a505Sdandb close 153651f3a505Sdanrename db2 db 153751f3a505Sdan 153848d9e01eSdan# EVIDENCE-OF: R-54898-34554 When casting a TEXT value to REAL, the 153948d9e01eSdan# longest possible prefix of the value that can be interpreted as a real 154048d9e01eSdan# number is extracted from the TEXT value and the remainder ignored. 154148d9e01eSdan# 154248d9e01eSdando_expr_test e_expr-29.2.1 { CAST('1.23abcd' AS REAL) } real 1.23 154348d9e01eSdando_expr_test e_expr-29.2.2 { CAST('1.45.23abcd' AS REAL) } real 1.45 154448d9e01eSdando_expr_test e_expr-29.2.3 { CAST('-2.12e-01ABC' AS REAL) } real -0.212 154548d9e01eSdando_expr_test e_expr-29.2.4 { CAST('1 2 3 4' AS REAL) } real 1.0 154651f3a505Sdan 154748d9e01eSdan# EVIDENCE-OF: R-11321-47427 Any leading spaces in the TEXT value are 154848d9e01eSdan# ignored when converging from TEXT to REAL. 154948d9e01eSdan# 155048d9e01eSdando_expr_test e_expr-29.3.1 { CAST(' 1.23abcd' AS REAL) } real 1.23 155148d9e01eSdando_expr_test e_expr-29.3.2 { CAST(' 1.45.23abcd' AS REAL) } real 1.45 155248d9e01eSdando_expr_test e_expr-29.3.3 { CAST(' -2.12e-01ABC' AS REAL) } real -0.212 155348d9e01eSdando_expr_test e_expr-29.3.4 { CAST(' 1 2 3 4' AS REAL) } real 1.0 155448d9e01eSdan 155548d9e01eSdan# EVIDENCE-OF: R-22662-28218 If there is no prefix that can be 155648d9e01eSdan# interpreted as a real number, the result of the conversion is 0.0. 155748d9e01eSdan# 155848d9e01eSdando_expr_test e_expr-29.4.1 { CAST('' AS REAL) } real 0.0 155948d9e01eSdando_expr_test e_expr-29.4.2 { CAST('not a number' AS REAL) } real 0.0 156048d9e01eSdando_expr_test e_expr-29.4.3 { CAST('XXI' AS REAL) } real 0.0 156148d9e01eSdan 156248d9e01eSdan# EVIDENCE-OF: R-21829-14563 When casting a BLOB value to INTEGER, the 156348d9e01eSdan# value is first converted to TEXT. 156448d9e01eSdan# 156548d9e01eSdando_expr_test e_expr-30.1.1 { CAST(X'313233' AS INTEGER) } integer 123 156648d9e01eSdando_expr_test e_expr-30.1.2 { CAST(X'2D363738' AS INTEGER) } integer -678 156748d9e01eSdando_expr_test e_expr-30.1.3 { 156848d9e01eSdan CAST(X'31303030303030' AS INTEGER) 156948d9e01eSdan} integer 1000000 157048d9e01eSdando_expr_test e_expr-30.1.4 { 157148d9e01eSdan CAST(X'2D31313235383939393036383432363234' AS INTEGER) 157248d9e01eSdan} integer -1125899906842624 157348d9e01eSdan 157448d9e01eSdanrename db db2 157548d9e01eSdansqlite3 db :memory: 15766faa5fdfSshanehifcapable {utf16} { 157748d9e01eSdanexecsql { PRAGMA encoding = 'utf-16be' } 157848d9e01eSdando_expr_test e_expr-30.1.5 { CAST(X'003100320033' AS INTEGER) } integer 123 157948d9e01eSdando_expr_test e_expr-30.1.6 { CAST(X'002D003600370038' AS INTEGER) } integer -678 158048d9e01eSdando_expr_test e_expr-30.1.7 { 158148d9e01eSdan CAST(X'0031003000300030003000300030' AS INTEGER) 158248d9e01eSdan} integer 1000000 158348d9e01eSdando_expr_test e_expr-30.1.8 { 158448d9e01eSdan CAST(X'002D0031003100320035003800390039003900300036003800340032003600320034' AS INTEGER) 158548d9e01eSdan} integer -1125899906842624 15866faa5fdfSshaneh} 158748d9e01eSdandb close 158848d9e01eSdanrename db2 db 158948d9e01eSdan 159048d9e01eSdan# EVIDENCE-OF: R-47612-45842 When casting a TEXT value to INTEGER, the 159148d9e01eSdan# longest possible prefix of the value that can be interpreted as an 159248d9e01eSdan# integer number is extracted from the TEXT value and the remainder 159348d9e01eSdan# ignored. 159448d9e01eSdan# 159548d9e01eSdando_expr_test e_expr-30.2.1 { CAST('123abcd' AS INT) } integer 123 159648d9e01eSdando_expr_test e_expr-30.2.2 { CAST('14523abcd' AS INT) } integer 14523 159748d9e01eSdando_expr_test e_expr-30.2.3 { CAST('-2.12e-01ABC' AS INT) } integer -2 159848d9e01eSdando_expr_test e_expr-30.2.4 { CAST('1 2 3 4' AS INT) } integer 1 159948d9e01eSdan 160048d9e01eSdan# EVIDENCE-OF: R-34400-33772 Any leading spaces in the TEXT value when 160148d9e01eSdan# converting from TEXT to INTEGER are ignored. 160248d9e01eSdan# 160348d9e01eSdando_expr_test e_expr-30.3.1 { CAST(' 123abcd' AS INT) } integer 123 160448d9e01eSdando_expr_test e_expr-30.3.2 { CAST(' 14523abcd' AS INT) } integer 14523 160548d9e01eSdando_expr_test e_expr-30.3.3 { CAST(' -2.12e-01ABC' AS INT) } integer -2 160648d9e01eSdando_expr_test e_expr-30.3.4 { CAST(' 1 2 3 4' AS INT) } integer 1 160748d9e01eSdan 160848d9e01eSdan# EVIDENCE-OF: R-43164-44276 If there is no prefix that can be 160948d9e01eSdan# interpreted as an integer number, the result of the conversion is 0. 161048d9e01eSdan# 161148d9e01eSdando_expr_test e_expr-30.4.1 { CAST('' AS INTEGER) } integer 0 161248d9e01eSdando_expr_test e_expr-30.4.2 { CAST('not a number' AS INTEGER) } integer 0 161348d9e01eSdando_expr_test e_expr-30.4.3 { CAST('XXI' AS INTEGER) } integer 0 161448d9e01eSdan 16159f959b07Sdrh# EVIDENCE-OF: R-08980-53124 The CAST operator understands decimal 16169f959b07Sdrh# integers only — conversion of hexadecimal integers stops at 16179f959b07Sdrh# the "x" in the "0x" prefix of the hexadecimal integer string and thus 16189f959b07Sdrh# result of the CAST is always zero. 16199f959b07Sdrhdo_expr_test e_expr-30.5.1 { CAST('0x1234' AS INTEGER) } integer 0 16209f959b07Sdrhdo_expr_test e_expr-30.5.2 { CAST('0X1234' AS INTEGER) } integer 0 16219f959b07Sdrh 16229338642cSdrh# EVIDENCE-OF: R-02752-50091 A cast of a REAL value into an INTEGER 16239338642cSdrh# results in the integer between the REAL value and zero that is closest 16249338642cSdrh# to the REAL value. 162548d9e01eSdan# 162648d9e01eSdando_expr_test e_expr-31.1.1 { CAST(3.14159 AS INTEGER) } integer 3 162748d9e01eSdando_expr_test e_expr-31.1.2 { CAST(1.99999 AS INTEGER) } integer 1 162848d9e01eSdando_expr_test e_expr-31.1.3 { CAST(-1.99999 AS INTEGER) } integer -1 162948d9e01eSdando_expr_test e_expr-31.1.4 { CAST(-0.99999 AS INTEGER) } integer 0 163048d9e01eSdan 16311bcbc6a6Sdrh# EVIDENCE-OF: R-51517-40824 If a REAL is greater than the greatest 16321bcbc6a6Sdrh# possible signed integer (+9223372036854775807) then the result is the 16331bcbc6a6Sdrh# greatest possible signed integer and if the REAL is less than the 16341bcbc6a6Sdrh# least possible signed integer (-9223372036854775808) then the result 16351bcbc6a6Sdrh# is the least possible signed integer. 163648d9e01eSdan# 1637de1a8b8cSdrhdo_expr_test e_expr-31.2.1 { CAST(2e+50 AS INT) } integer 9223372036854775807 163848d9e01eSdando_expr_test e_expr-31.2.2 { CAST(-2e+50 AS INT) } integer -9223372036854775808 163948d9e01eSdando_expr_test e_expr-31.2.3 { 164048d9e01eSdan CAST(-9223372036854775809.0 AS INT) 164148d9e01eSdan} integer -9223372036854775808 164248d9e01eSdando_expr_test e_expr-31.2.4 { 164348d9e01eSdan CAST(9223372036854775809.0 AS INT) 1644de1a8b8cSdrh} integer 9223372036854775807 164548d9e01eSdan 164648d9e01eSdan 164748d9e01eSdan# EVIDENCE-OF: R-09295-61337 Casting a TEXT or BLOB value into NUMERIC 164848d9e01eSdan# first does a forced conversion into REAL but then further converts the 164948d9e01eSdan# result into INTEGER if and only if the conversion from REAL to INTEGER 165048d9e01eSdan# is lossless and reversible. 165148d9e01eSdan# 165248d9e01eSdando_expr_test e_expr-32.1.1 { CAST('45' AS NUMERIC) } integer 45 165348d9e01eSdando_expr_test e_expr-32.1.2 { CAST('45.0' AS NUMERIC) } integer 45 165448d9e01eSdando_expr_test e_expr-32.1.3 { CAST('45.2' AS NUMERIC) } real 45.2 165548d9e01eSdando_expr_test e_expr-32.1.4 { CAST('11abc' AS NUMERIC) } integer 11 165648d9e01eSdando_expr_test e_expr-32.1.5 { CAST('11.1abc' AS NUMERIC) } real 11.1 165748d9e01eSdan 165848d9e01eSdan# EVIDENCE-OF: R-30347-18702 Casting a REAL or INTEGER value to NUMERIC 165948d9e01eSdan# is a no-op, even if a real value could be losslessly converted to an 166048d9e01eSdan# integer. 166148d9e01eSdan# 166248d9e01eSdando_expr_test e_expr-32.2.1 { CAST(13.0 AS NUMERIC) } real 13.0 166348d9e01eSdando_expr_test e_expr-32.2.2 { CAST(13.5 AS NUMERIC) } real 13.5 166448d9e01eSdan 166548d9e01eSdando_expr_test e_expr-32.2.3 { 166648d9e01eSdan CAST(-9223372036854775808 AS NUMERIC) 166748d9e01eSdan} integer -9223372036854775808 166848d9e01eSdando_expr_test e_expr-32.2.4 { 166948d9e01eSdan CAST(9223372036854775807 AS NUMERIC) 167048d9e01eSdan} integer 9223372036854775807 167184d4f1a3Sdrhdo_expr_test e_expr-32.2.5 { 167284d4f1a3Sdrh CAST('9223372036854775807 ' AS NUMERIC) 167384d4f1a3Sdrh} integer 9223372036854775807 167484d4f1a3Sdrhdo_expr_test e_expr-32.2.6 { 167584d4f1a3Sdrh CAST(' 9223372036854775807 ' AS NUMERIC) 167684d4f1a3Sdrh} integer 9223372036854775807 167784d4f1a3Sdrhdo_expr_test e_expr-32.2.7 { 167884d4f1a3Sdrh CAST(' ' AS NUMERIC) 167984d4f1a3Sdrh} integer 0 168084d4f1a3Sdrhdo_execsql_test e_expr-32.2.8 { 168184d4f1a3Sdrh WITH t1(x) AS (VALUES 168284d4f1a3Sdrh ('9000000000000000001'), 168384d4f1a3Sdrh ('9000000000000000001x'), 168484d4f1a3Sdrh ('9000000000000000001 '), 168584d4f1a3Sdrh (' 9000000000000000001 '), 168684d4f1a3Sdrh (' 9000000000000000001'), 168784d4f1a3Sdrh (' 9000000000000000001.'), 168884d4f1a3Sdrh ('9223372036854775807'), 168984d4f1a3Sdrh ('9223372036854775807 '), 169084d4f1a3Sdrh (' 9223372036854775807 '), 169184d4f1a3Sdrh ('9223372036854775808'), 169284d4f1a3Sdrh (' 9223372036854775808 '), 169384d4f1a3Sdrh ('9223372036854775807.0'), 169484d4f1a3Sdrh ('9223372036854775807e+0'), 169584d4f1a3Sdrh ('-5.0'), 169684d4f1a3Sdrh ('-5e+0')) 169784d4f1a3Sdrh SELECT typeof(CAST(x AS NUMERIC)), CAST(x AS NUMERIC)||'' FROM t1; 169884d4f1a3Sdrh} [list \ 169984d4f1a3Sdrh integer 9000000000000000001 \ 170084d4f1a3Sdrh integer 9000000000000000001 \ 170184d4f1a3Sdrh integer 9000000000000000001 \ 170284d4f1a3Sdrh integer 9000000000000000001 \ 170384d4f1a3Sdrh integer 9000000000000000001 \ 170484d4f1a3Sdrh integer 9000000000000000001 \ 170584d4f1a3Sdrh integer 9223372036854775807 \ 170684d4f1a3Sdrh integer 9223372036854775807 \ 170784d4f1a3Sdrh integer 9223372036854775807 \ 170884d4f1a3Sdrh real 9.22337203685478e+18 \ 170984d4f1a3Sdrh real 9.22337203685478e+18 \ 171084d4f1a3Sdrh integer 9223372036854775807 \ 171184d4f1a3Sdrh integer 9223372036854775807 \ 171284d4f1a3Sdrh integer -5 \ 171384d4f1a3Sdrh integer -5 \ 171484d4f1a3Sdrh] 171548d9e01eSdan 171648d9e01eSdan# EVIDENCE-OF: R-64550-29191 Note that the result from casting any 171748d9e01eSdan# non-BLOB value into a BLOB and the result from casting any BLOB value 171848d9e01eSdan# into a non-BLOB value may be different depending on whether the 171948d9e01eSdan# database encoding is UTF-8, UTF-16be, or UTF-16le. 172048d9e01eSdan# 17216faa5fdfSshanehifcapable {utf16} { 172248d9e01eSdansqlite3 db1 :memory: ; db1 eval { PRAGMA encoding = 'utf-8' } 172348d9e01eSdansqlite3 db2 :memory: ; db2 eval { PRAGMA encoding = 'utf-16le' } 172448d9e01eSdansqlite3 db3 :memory: ; db3 eval { PRAGMA encoding = 'utf-16be' } 172548d9e01eSdanforeach {tn castexpr differs} { 172648d9e01eSdan 1 { CAST(123 AS BLOB) } 1 172748d9e01eSdan 2 { CAST('' AS BLOB) } 0 172848d9e01eSdan 3 { CAST('abcd' AS BLOB) } 1 172948d9e01eSdan 173048d9e01eSdan 4 { CAST(X'abcd' AS TEXT) } 1 173148d9e01eSdan 5 { CAST(X'' AS TEXT) } 0 173248d9e01eSdan} { 173348d9e01eSdan set r1 [db1 eval "SELECT typeof($castexpr), quote($castexpr)"] 173448d9e01eSdan set r2 [db2 eval "SELECT typeof($castexpr), quote($castexpr)"] 173548d9e01eSdan set r3 [db3 eval "SELECT typeof($castexpr), quote($castexpr)"] 173648d9e01eSdan 173748d9e01eSdan if {$differs} { 173848d9e01eSdan set res [expr {$r1!=$r2 && $r2!=$r3}] 173948d9e01eSdan } else { 174048d9e01eSdan set res [expr {$r1==$r2 && $r2==$r3}] 174148d9e01eSdan } 174248d9e01eSdan 174348d9e01eSdan do_test e_expr-33.1.$tn {set res} 1 174448d9e01eSdan} 174548d9e01eSdandb1 close 174648d9e01eSdandb2 close 174748d9e01eSdandb3 close 17486faa5fdfSshaneh} 174948d9e01eSdan 17504336cc45Sdan#------------------------------------------------------------------------- 17514336cc45Sdan# Test statements related to the EXISTS and NOT EXISTS operators. 17524336cc45Sdan# 17534336cc45Sdancatch { db close } 1754fda06befSmistachkinforcedelete test.db 17554336cc45Sdansqlite3 db test.db 17564336cc45Sdan 17574336cc45Sdando_execsql_test e_expr-34.1 { 17584336cc45Sdan CREATE TABLE t1(a, b); 17594336cc45Sdan INSERT INTO t1 VALUES(1, 2); 17604336cc45Sdan INSERT INTO t1 VALUES(NULL, 2); 17614336cc45Sdan INSERT INTO t1 VALUES(1, NULL); 17624336cc45Sdan INSERT INTO t1 VALUES(NULL, NULL); 17634336cc45Sdan} {} 17644336cc45Sdan 17654336cc45Sdan# EVIDENCE-OF: R-25588-27181 The EXISTS operator always evaluates to one 17664336cc45Sdan# of the integer values 0 and 1. 17674336cc45Sdan# 17684336cc45Sdan# This statement is not tested by itself. Instead, all e_expr-34.* tests 17694336cc45Sdan# following this point explicitly test that specific invocations of EXISTS 17704336cc45Sdan# return either integer 0 or integer 1. 17714336cc45Sdan# 17724336cc45Sdan 17734336cc45Sdan# EVIDENCE-OF: R-58553-63740 If executing the SELECT statement specified 17744336cc45Sdan# as the right-hand operand of the EXISTS operator would return one or 17754336cc45Sdan# more rows, then the EXISTS operator evaluates to 1. 17764336cc45Sdan# 17774336cc45Sdanforeach {tn expr} { 17784336cc45Sdan 1 { EXISTS ( SELECT a FROM t1 ) } 17794336cc45Sdan 2 { EXISTS ( SELECT b FROM t1 ) } 17804336cc45Sdan 3 { EXISTS ( SELECT 24 ) } 17814336cc45Sdan 4 { EXISTS ( SELECT NULL ) } 17824336cc45Sdan 5 { EXISTS ( SELECT a FROM t1 WHERE a IS NULL ) } 17834336cc45Sdan} { 17844336cc45Sdan do_expr_test e_expr-34.2.$tn $expr integer 1 17854336cc45Sdan} 17864336cc45Sdan 17874336cc45Sdan# EVIDENCE-OF: R-19673-40972 If executing the SELECT would return no 17884336cc45Sdan# rows at all, then the EXISTS operator evaluates to 0. 17894336cc45Sdan# 17904336cc45Sdanforeach {tn expr} { 17914336cc45Sdan 1 { EXISTS ( SELECT a FROM t1 WHERE 0) } 17924336cc45Sdan 2 { EXISTS ( SELECT b FROM t1 WHERE a = 5) } 17934336cc45Sdan 3 { EXISTS ( SELECT 24 WHERE 0) } 17944336cc45Sdan 4 { EXISTS ( SELECT NULL WHERE 1=2) } 17954336cc45Sdan} { 17964336cc45Sdan do_expr_test e_expr-34.3.$tn $expr integer 0 17974336cc45Sdan} 17984336cc45Sdan 17994336cc45Sdan# EVIDENCE-OF: R-35109-49139 The number of columns in each row returned 18004336cc45Sdan# by the SELECT statement (if any) and the specific values returned have 18014336cc45Sdan# no effect on the results of the EXISTS operator. 18024336cc45Sdan# 18034336cc45Sdanforeach {tn expr res} { 18044336cc45Sdan 1 { EXISTS ( SELECT * FROM t1 ) } 1 18054336cc45Sdan 2 { EXISTS ( SELECT *, *, * FROM t1 ) } 1 18064336cc45Sdan 3 { EXISTS ( SELECT 24, 25 ) } 1 18074336cc45Sdan 4 { EXISTS ( SELECT NULL, NULL, NULL ) } 1 18084336cc45Sdan 5 { EXISTS ( SELECT a,b,a||b FROM t1 WHERE a IS NULL ) } 1 18094336cc45Sdan 18104336cc45Sdan 6 { EXISTS ( SELECT a, a FROM t1 WHERE 0) } 0 18114336cc45Sdan 7 { EXISTS ( SELECT b, b, a FROM t1 WHERE a = 5) } 0 18124336cc45Sdan 8 { EXISTS ( SELECT 24, 46, 89 WHERE 0) } 0 18134336cc45Sdan 9 { EXISTS ( SELECT NULL, NULL WHERE 1=2) } 0 18144336cc45Sdan} { 18154336cc45Sdan do_expr_test e_expr-34.4.$tn $expr integer $res 18164336cc45Sdan} 18174336cc45Sdan 18184336cc45Sdan# EVIDENCE-OF: R-10645-12439 In particular, rows containing NULL values 18194336cc45Sdan# are not handled any differently from rows without NULL values. 18204336cc45Sdan# 18214336cc45Sdanforeach {tn e1 e2} { 18224336cc45Sdan 1 { EXISTS (SELECT 'not null') } { EXISTS (SELECT NULL) } 18234336cc45Sdan 2 { EXISTS (SELECT NULL FROM t1) } { EXISTS (SELECT 'bread' FROM t1) } 18244336cc45Sdan} { 18254336cc45Sdan set res [db one "SELECT $e1"] 18264336cc45Sdan do_expr_test e_expr-34.5.${tn}a $e1 integer $res 18274336cc45Sdan do_expr_test e_expr-34.5.${tn}b $e2 integer $res 18284336cc45Sdan} 18294336cc45Sdan 18304336cc45Sdan#------------------------------------------------------------------------- 183174b617b2Sdan# Test statements related to scalar sub-queries. 18324336cc45Sdan# 18334336cc45Sdan 183474b617b2Sdancatch { db close } 1835fda06befSmistachkinforcedelete test.db 183674b617b2Sdansqlite3 db test.db 183774b617b2Sdando_test e_expr-35.0 { 183874b617b2Sdan execsql { 183974b617b2Sdan CREATE TABLE t2(a, b); 184074b617b2Sdan INSERT INTO t2 VALUES('one', 'two'); 184174b617b2Sdan INSERT INTO t2 VALUES('three', NULL); 184274b617b2Sdan INSERT INTO t2 VALUES(4, 5.0); 184374b617b2Sdan } 184474b617b2Sdan} {} 184574b617b2Sdan 184650da6635Sdrh# EVIDENCE-OF: R-43573-23448 A SELECT statement enclosed in parentheses 184750da6635Sdrh# is a subquery. 184874b617b2Sdan# 184974b617b2Sdan# EVIDENCE-OF: R-56294-03966 All types of SELECT statement, including 185074b617b2Sdan# aggregate and compound SELECT queries (queries with keywords like 185174b617b2Sdan# UNION or EXCEPT) are allowed as scalar subqueries. 185274b617b2Sdan# 185374b617b2Sdando_expr_test e_expr-35.1.1 { (SELECT 35) } integer 35 185474b617b2Sdando_expr_test e_expr-35.1.2 { (SELECT NULL) } null {} 185574b617b2Sdan 185674b617b2Sdando_expr_test e_expr-35.1.3 { (SELECT count(*) FROM t2) } integer 3 185774b617b2Sdando_expr_test e_expr-35.1.4 { (SELECT 4 FROM t2) } integer 4 185874b617b2Sdan 185974b617b2Sdando_expr_test e_expr-35.1.5 { 186074b617b2Sdan (SELECT b FROM t2 UNION SELECT a+1 FROM t2) 186174b617b2Sdan} null {} 186274b617b2Sdando_expr_test e_expr-35.1.6 { 186374b617b2Sdan (SELECT a FROM t2 UNION SELECT COALESCE(b, 55) FROM t2 ORDER BY 1) 186474b617b2Sdan} integer 4 186574b617b2Sdan 186650da6635Sdrh# EVIDENCE-OF: R-22239-33740 A subquery that returns two or more columns 186750da6635Sdrh# is a row value subquery and can only be used as the operand of a 186850da6635Sdrh# comparison operator. 186974b617b2Sdan# 187006ce4136Sdan# The following block tests that errors are returned in a bunch of cases 187106ce4136Sdan# where a subquery returns more than one column. 187206ce4136Sdan# 18738da209b1Sdanset M {/1 {sub-select returns [23] columns - expected 1}/} 187474b617b2Sdanforeach {tn sql} { 187574b617b2Sdan 1 { SELECT (SELECT * FROM t2 UNION SELECT a+1, b+1 FROM t2) } 187674b617b2Sdan 2 { SELECT (SELECT * FROM t2 UNION SELECT a+1, b+1 FROM t2 ORDER BY 1) } 187774b617b2Sdan 3 { SELECT (SELECT 1, 2) } 187874b617b2Sdan 4 { SELECT (SELECT NULL, NULL, NULL) } 187974b617b2Sdan 5 { SELECT (SELECT * FROM t2) } 188074b617b2Sdan 6 { SELECT (SELECT * FROM (SELECT 1, 2, 3)) } 188174b617b2Sdan} { 18828da209b1Sdan do_catchsql_test e_expr-35.2.$tn $sql $M 188374b617b2Sdan} 188474b617b2Sdan 188550da6635Sdrh# EVIDENCE-OF: R-18318-14995 The value of a subquery expression is the 188650da6635Sdrh# first row of the result from the enclosed SELECT statement. 188706ce4136Sdan# 188850da6635Sdrh# EVIDENCE-OF: R-15900-52156 In other words, an implied "LIMIT 1" is 188950da6635Sdrh# added to the subquery, overriding an explicitly coded LIMIT. 189006ce4136Sdan# 189106ce4136Sdando_execsql_test e_expr-36.3.1 { 189206ce4136Sdan CREATE TABLE t4(x, y); 189306ce4136Sdan INSERT INTO t4 VALUES(1, 'one'); 189406ce4136Sdan INSERT INTO t4 VALUES(2, 'two'); 189506ce4136Sdan INSERT INTO t4 VALUES(3, 'three'); 189606ce4136Sdan} {} 189706ce4136Sdan 189806ce4136Sdanforeach {tn expr restype resval} { 189906ce4136Sdan 2 { ( SELECT x FROM t4 ORDER BY x ) } integer 1 190006ce4136Sdan 3 { ( SELECT x FROM t4 ORDER BY y ) } integer 1 190106ce4136Sdan 4 { ( SELECT x FROM t4 ORDER BY x DESC ) } integer 3 190206ce4136Sdan 5 { ( SELECT x FROM t4 ORDER BY y DESC ) } integer 2 190306ce4136Sdan 6 { ( SELECT y FROM t4 ORDER BY y DESC ) } text two 190406ce4136Sdan 190506ce4136Sdan 7 { ( SELECT sum(x) FROM t4 ) } integer 6 190606ce4136Sdan 8 { ( SELECT group_concat(y,'') FROM t4 ) } text onetwothree 190706ce4136Sdan 9 { ( SELECT max(x) FROM t4 WHERE y LIKE '___') } integer 2 190806ce4136Sdan 190906ce4136Sdan} { 191006ce4136Sdan do_expr_test e_expr-36.3.$tn $expr $restype $resval 191106ce4136Sdan} 191206ce4136Sdan 191350da6635Sdrh# EVIDENCE-OF: R-52325-25449 The value of a subquery expression is NULL 191450da6635Sdrh# if the enclosed SELECT statement returns no rows. 191506ce4136Sdan# 191606ce4136Sdanforeach {tn expr} { 191706ce4136Sdan 1 { ( SELECT x FROM t4 WHERE x>3 ORDER BY x ) } 191806ce4136Sdan 2 { ( SELECT x FROM t4 WHERE y<'one' ORDER BY y ) } 191906ce4136Sdan} { 192006ce4136Sdan do_expr_test e_expr-36.4.$tn $expr null {} 192106ce4136Sdan} 192206ce4136Sdan 19232c7e9bfcSdrh# EVIDENCE-OF: R-62477-06476 For example, the values NULL, 0.0, 0, 19242c7e9bfcSdrh# 'english' and '0' are all considered to be false. 19252c7e9bfcSdrh# 19262c7e9bfcSdrhdo_execsql_test e_expr-37.1 { 19272c7e9bfcSdrh SELECT CASE WHEN NULL THEN 'true' ELSE 'false' END; 19282c7e9bfcSdrh} {false} 19292c7e9bfcSdrhdo_execsql_test e_expr-37.2 { 19302c7e9bfcSdrh SELECT CASE WHEN 0.0 THEN 'true' ELSE 'false' END; 19312c7e9bfcSdrh} {false} 19322c7e9bfcSdrhdo_execsql_test e_expr-37.3 { 19332c7e9bfcSdrh SELECT CASE WHEN 0 THEN 'true' ELSE 'false' END; 19342c7e9bfcSdrh} {false} 19352c7e9bfcSdrhdo_execsql_test e_expr-37.4 { 19362c7e9bfcSdrh SELECT CASE WHEN 'engligh' THEN 'true' ELSE 'false' END; 19372c7e9bfcSdrh} {false} 19382c7e9bfcSdrhdo_execsql_test e_expr-37.5 { 19392c7e9bfcSdrh SELECT CASE WHEN '0' THEN 'true' ELSE 'false' END; 19402c7e9bfcSdrh} {false} 19412c7e9bfcSdrh 19422c7e9bfcSdrh# EVIDENCE-OF: R-55532-10108 Values 1, 1.0, 0.1, -0.1 and '1english' are 19432c7e9bfcSdrh# considered to be true. 19442c7e9bfcSdrh# 19452c7e9bfcSdrhdo_execsql_test e_expr-37.6 { 19462c7e9bfcSdrh SELECT CASE WHEN 1 THEN 'true' ELSE 'false' END; 19472c7e9bfcSdrh} {true} 19482c7e9bfcSdrhdo_execsql_test e_expr-37.7 { 19492c7e9bfcSdrh SELECT CASE WHEN 1.0 THEN 'true' ELSE 'false' END; 19502c7e9bfcSdrh} {true} 19512c7e9bfcSdrhdo_execsql_test e_expr-37.8 { 19522c7e9bfcSdrh SELECT CASE WHEN 0.1 THEN 'true' ELSE 'false' END; 19532c7e9bfcSdrh} {true} 19542c7e9bfcSdrhdo_execsql_test e_expr-37.9 { 19552c7e9bfcSdrh SELECT CASE WHEN -0.1 THEN 'true' ELSE 'false' END; 19562c7e9bfcSdrh} {true} 19572c7e9bfcSdrhdo_execsql_test e_expr-37.10 { 19582c7e9bfcSdrh SELECT CASE WHEN '1english' THEN 'true' ELSE 'false' END; 19592c7e9bfcSdrh} {true} 19602c7e9bfcSdrh 196106ce4136Sdan 196248d9e01eSdanfinish_test 1963