xref: /sqlite-3.40.0/test/e_expr.test (revision 4d7f335e)
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#
87c0bd26a2Sdrh# X-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#
92c0bd26a2Sdrh# X-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#
183c0bd26a2Sdrh# X-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#
25768b40344Sdrh# EVIDENCE-OF: R-53431-59159 The % operator casts both of its operands
25868b40344Sdrh# to type INTEGER and then computes the remainder after dividing the
25968b40344Sdrh# left integer by the right integer.
260784141eaSdan#
261784141eaSdando_execsql_test e_expr-6.1 {SELECT  72%5}  {2}
262784141eaSdando_execsql_test e_expr-6.2 {SELECT  72%-5} {2}
263784141eaSdando_execsql_test e_expr-6.3 {SELECT -72%-5} {-2}
264784141eaSdando_execsql_test e_expr-6.4 {SELECT -72%5}  {-2}
265923260c8Sdrhdo_execsql_test e_expr-6.5 {SELECT 72.35%5} {2.0}
266784141eaSdan
267784141eaSdan#-------------------------------------------------------------------------
268*4d7f335eSdrh# EVIDENCE-OF: R-15904-00746 The result of any binary operator is either
269*4d7f335eSdrh# a numeric value or NULL, except for the || concatenation operator, and
270*4d7f335eSdrh# the -> and ->> extract operators which evaluate to either
271*4d7f335eSdrh# NULL or a text value.
272784141eaSdan#
273784141eaSdanset literals {
274784141eaSdan  1 'abc'        2 'hexadecimal'       3 ''
275784141eaSdan  4 123          5 -123                6 0
276784141eaSdan  7 123.4        8 0.0                 9 -123.4
277784141eaSdan 10 X'ABCDEF'   11 X''                12 X'0000'
278784141eaSdan 13     NULL
279784141eaSdan}
280784141eaSdanforeach op $oplist {
281784141eaSdan  foreach {n1 rhs} $literals {
282784141eaSdan  foreach {n2 lhs} $literals {
283784141eaSdan
284784141eaSdan    set t [db one " SELECT typeof($lhs $op $rhs) "]
285784141eaSdan    do_test e_expr-7.$opname($op).$n1.$n2 {
286784141eaSdan      expr {
287784141eaSdan           ($op=="||" && ($t == "text" || $t == "null"))
288784141eaSdan        || ($op!="||" && ($t == "integer" || $t == "real" || $t == "null"))
289784141eaSdan      }
290784141eaSdan    } 1
291784141eaSdan
292784141eaSdan  }}
293784141eaSdan}
294784141eaSdan
295784141eaSdan#-------------------------------------------------------------------------
296784141eaSdan# Test the IS and IS NOT operators.
297784141eaSdan#
298784141eaSdan# EVIDENCE-OF: R-24731-45773 The IS and IS NOT operators work like = and
299784141eaSdan# != except when one or both of the operands are NULL.
300784141eaSdan#
301784141eaSdan# EVIDENCE-OF: R-06325-15315 In this case, if both operands are NULL,
302784141eaSdan# then the IS operator evaluates to 1 (true) and the IS NOT operator
303784141eaSdan# evaluates to 0 (false).
304784141eaSdan#
305784141eaSdan# EVIDENCE-OF: R-19812-36779 If one operand is NULL and the other is
306784141eaSdan# not, then the IS operator evaluates to 0 (false) and the IS NOT
307784141eaSdan# operator is 1 (true).
308784141eaSdan#
309784141eaSdan# EVIDENCE-OF: R-61975-13410 It is not possible for an IS or IS NOT
310784141eaSdan# expression to evaluate to NULL.
311784141eaSdan#
312784141eaSdando_execsql_test e_expr-8.1.1  { SELECT NULL IS     NULL } {1}
313784141eaSdando_execsql_test e_expr-8.1.2  { SELECT 'ab' IS     NULL } {0}
314784141eaSdando_execsql_test e_expr-8.1.3  { SELECT NULL IS     'ab' } {0}
315784141eaSdando_execsql_test e_expr-8.1.4  { SELECT 'ab' IS     'ab' } {1}
316784141eaSdando_execsql_test e_expr-8.1.5  { SELECT NULL ==     NULL } {{}}
317784141eaSdando_execsql_test e_expr-8.1.6  { SELECT 'ab' ==     NULL } {{}}
318784141eaSdando_execsql_test e_expr-8.1.7  { SELECT NULL ==     'ab' } {{}}
319784141eaSdando_execsql_test e_expr-8.1.8  { SELECT 'ab' ==     'ab' } {1}
320784141eaSdando_execsql_test e_expr-8.1.9  { SELECT NULL IS NOT NULL } {0}
321784141eaSdando_execsql_test e_expr-8.1.10 { SELECT 'ab' IS NOT NULL } {1}
322784141eaSdando_execsql_test e_expr-8.1.11 { SELECT NULL IS NOT 'ab' } {1}
323784141eaSdando_execsql_test e_expr-8.1.12 { SELECT 'ab' IS NOT 'ab' } {0}
324784141eaSdando_execsql_test e_expr-8.1.13 { SELECT NULL !=     NULL } {{}}
325784141eaSdando_execsql_test e_expr-8.1.14 { SELECT 'ab' !=     NULL } {{}}
326784141eaSdando_execsql_test e_expr-8.1.15 { SELECT NULL !=     'ab' } {{}}
327784141eaSdando_execsql_test e_expr-8.1.16 { SELECT 'ab' !=     'ab' } {0}
328784141eaSdan
329784141eaSdanforeach {n1 rhs} $literals {
330784141eaSdan  foreach {n2 lhs} $literals {
331784141eaSdan    if {$rhs!="NULL" && $lhs!="NULL"} {
332784141eaSdan      set eq [execsql "SELECT $lhs = $rhs, $lhs != $rhs"]
333784141eaSdan    } else {
334784141eaSdan      set eq [list [expr {$lhs=="NULL" && $rhs=="NULL"}] \
335784141eaSdan                   [expr {$lhs!="NULL" || $rhs!="NULL"}]
336784141eaSdan      ]
337784141eaSdan    }
338784141eaSdan    set test e_expr-8.2.$n1.$n2
339784141eaSdan    do_execsql_test $test.1 "SELECT $lhs IS $rhs, $lhs IS NOT $rhs" $eq
340784141eaSdan    do_execsql_test $test.2 "
341784141eaSdan      SELECT ($lhs IS $rhs) IS NULL, ($lhs IS NOT $rhs) IS NULL
342784141eaSdan    " {0 0}
343784141eaSdan  }
344784141eaSdan}
345784141eaSdan
346c29486a2Sdan#-------------------------------------------------------------------------
347c29486a2Sdan# Run some tests on the COLLATE "unary postfix operator".
348c29486a2Sdan#
349c29486a2Sdan# This collation sequence reverses both arguments before using
350c29486a2Sdan# [string compare] to compare them. For example, when comparing the
351c29486a2Sdan# strings 'one' and 'four', return the result of:
352c29486a2Sdan#
353c29486a2Sdan#   string compare eno ruof
354c29486a2Sdan#
355c29486a2Sdanproc reverse_str {zStr} {
356c29486a2Sdan  set out ""
357c29486a2Sdan  foreach c [split $zStr {}] { set out "${c}${out}" }
358c29486a2Sdan  set out
359c29486a2Sdan}
360c29486a2Sdanproc reverse_collate {zLeft zRight} {
361c29486a2Sdan  string compare [reverse_str $zLeft] [reverse_str $zRight]
362c29486a2Sdan}
363c29486a2Sdandb collate reverse reverse_collate
364c29486a2Sdan
365c29486a2Sdan# EVIDENCE-OF: R-59577-33471 The COLLATE operator is a unary postfix
366c29486a2Sdan# operator that assigns a collating sequence to an expression.
367c29486a2Sdan#
368c0bd26a2Sdrh# X-EVIDENCE-OF: R-36231-30731 The COLLATE operator has a higher
36939759747Sdrh# precedence (binds more tightly) than any binary operator and any unary
37039759747Sdrh# prefix operator except "~".
371c29486a2Sdan#
372c29486a2Sdando_execsql_test e_expr-9.1 { SELECT  'abcd' < 'bbbb'    COLLATE reverse } 0
373c29486a2Sdando_execsql_test e_expr-9.2 { SELECT ('abcd' < 'bbbb')   COLLATE reverse } 1
374c29486a2Sdando_execsql_test e_expr-9.3 { SELECT  'abcd' <= 'bbbb'   COLLATE reverse } 0
375c29486a2Sdando_execsql_test e_expr-9.4 { SELECT ('abcd' <= 'bbbb')  COLLATE reverse } 1
376c29486a2Sdan
377c29486a2Sdando_execsql_test e_expr-9.5 { SELECT  'abcd' > 'bbbb'    COLLATE reverse } 1
378c29486a2Sdando_execsql_test e_expr-9.6 { SELECT ('abcd' > 'bbbb')   COLLATE reverse } 0
379c29486a2Sdando_execsql_test e_expr-9.7 { SELECT  'abcd' >= 'bbbb'   COLLATE reverse } 1
380c29486a2Sdando_execsql_test e_expr-9.8 { SELECT ('abcd' >= 'bbbb')  COLLATE reverse } 0
381c29486a2Sdan
382c29486a2Sdando_execsql_test e_expr-9.10 { SELECT  'abcd' =  'ABCD'  COLLATE nocase } 1
383c29486a2Sdando_execsql_test e_expr-9.11 { SELECT ('abcd' =  'ABCD') COLLATE nocase } 0
384c29486a2Sdando_execsql_test e_expr-9.12 { SELECT  'abcd' == 'ABCD'  COLLATE nocase } 1
385c29486a2Sdando_execsql_test e_expr-9.13 { SELECT ('abcd' == 'ABCD') COLLATE nocase } 0
386c29486a2Sdando_execsql_test e_expr-9.14 { SELECT  'abcd' IS 'ABCD'  COLLATE nocase } 1
387c29486a2Sdando_execsql_test e_expr-9.15 { SELECT ('abcd' IS 'ABCD') COLLATE nocase } 0
388c29486a2Sdan
389c29486a2Sdando_execsql_test e_expr-9.16 { SELECT  'abcd' != 'ABCD'      COLLATE nocase } 0
390c29486a2Sdando_execsql_test e_expr-9.17 { SELECT ('abcd' != 'ABCD')     COLLATE nocase } 1
391c29486a2Sdando_execsql_test e_expr-9.18 { SELECT  'abcd' <> 'ABCD'      COLLATE nocase } 0
392c29486a2Sdando_execsql_test e_expr-9.19 { SELECT ('abcd' <> 'ABCD')     COLLATE nocase } 1
393c29486a2Sdando_execsql_test e_expr-9.20 { SELECT  'abcd' IS NOT 'ABCD'  COLLATE nocase } 0
394c29486a2Sdando_execsql_test e_expr-9.21 { SELECT ('abcd' IS NOT 'ABCD') COLLATE nocase } 1
395c29486a2Sdan
396c29486a2Sdando_execsql_test e_expr-9.22 {
397c29486a2Sdan  SELECT 'bbb' BETWEEN 'AAA' AND 'CCC' COLLATE nocase
398c29486a2Sdan} 1
399c29486a2Sdando_execsql_test e_expr-9.23 {
400c29486a2Sdan  SELECT ('bbb' BETWEEN 'AAA' AND 'CCC') COLLATE nocase
401c29486a2Sdan} 0
402c29486a2Sdan
403c29486a2Sdan# EVIDENCE-OF: R-58731-25439 The collating sequence set by the COLLATE
404c29486a2Sdan# operator overrides the collating sequence determined by the COLLATE
405c29486a2Sdan# clause in a table column definition.
406c29486a2Sdan#
407c29486a2Sdando_execsql_test e_expr-9.24 {
408c29486a2Sdan  CREATE TABLE t24(a COLLATE NOCASE, b);
409c29486a2Sdan  INSERT INTO t24 VALUES('aaa', 1);
410c29486a2Sdan  INSERT INTO t24 VALUES('bbb', 2);
411c29486a2Sdan  INSERT INTO t24 VALUES('ccc', 3);
412c29486a2Sdan} {}
413c29486a2Sdando_execsql_test e_expr-9.25 { SELECT 'BBB' = a FROM t24 } {0 1 0}
414c29486a2Sdando_execsql_test e_expr-9.25 { SELECT a = 'BBB' FROM t24 } {0 1 0}
415c29486a2Sdando_execsql_test e_expr-9.25 { SELECT 'BBB' = a COLLATE binary FROM t24 } {0 0 0}
416c29486a2Sdando_execsql_test e_expr-9.25 { SELECT a COLLATE binary = 'BBB' FROM t24 } {0 0 0}
417c29486a2Sdan
418c29486a2Sdan#-------------------------------------------------------------------------
419c29486a2Sdan# Test statements related to literal values.
420c29486a2Sdan#
421c29486a2Sdan# EVIDENCE-OF: R-31536-32008 Literal values may be integers, floating
422c29486a2Sdan# point numbers, strings, BLOBs, or NULLs.
423c29486a2Sdan#
424c29486a2Sdando_execsql_test e_expr-10.1.1 { SELECT typeof(5)       } {integer}
425c29486a2Sdando_execsql_test e_expr-10.1.2 { SELECT typeof(5.1)     } {real}
426c29486a2Sdando_execsql_test e_expr-10.1.3 { SELECT typeof('5.1')   } {text}
427c29486a2Sdando_execsql_test e_expr-10.1.4 { SELECT typeof(X'ABCD') } {blob}
428c29486a2Sdando_execsql_test e_expr-10.1.5 { SELECT typeof(NULL)    } {null}
429c29486a2Sdan
43055f1da09Sdan# "Scientific notation is supported for point literal values."
431c29486a2Sdan#
432c29486a2Sdando_execsql_test e_expr-10.2.1 { SELECT typeof(3.4e-02)    } {real}
433c29486a2Sdando_execsql_test e_expr-10.2.2 { SELECT typeof(3e+5)       } {real}
434c29486a2Sdando_execsql_test e_expr-10.2.3 { SELECT 3.4e-02            } {0.034}
435c29486a2Sdando_execsql_test e_expr-10.2.4 { SELECT 3e+4               } {30000.0}
436c29486a2Sdan
437c29486a2Sdan# EVIDENCE-OF: R-35229-17830 A string constant is formed by enclosing
438c29486a2Sdan# the string in single quotes (').
439c29486a2Sdan#
440c29486a2Sdan# EVIDENCE-OF: R-07100-06606 A single quote within the string can be
441c29486a2Sdan# encoded by putting two single quotes in a row - as in Pascal.
442c29486a2Sdan#
443c29486a2Sdando_execsql_test e_expr-10.3.1 { SELECT 'is not' }         {{is not}}
444c29486a2Sdando_execsql_test e_expr-10.3.2 { SELECT typeof('is not') } {text}
445c29486a2Sdando_execsql_test e_expr-10.3.3 { SELECT 'isn''t' }         {isn't}
446c29486a2Sdando_execsql_test e_expr-10.3.4 { SELECT typeof('isn''t') } {text}
447c29486a2Sdan
448c29486a2Sdan# EVIDENCE-OF: R-09593-03321 BLOB literals are string literals
449c29486a2Sdan# containing hexadecimal data and preceded by a single "x" or "X"
450c29486a2Sdan# character.
451c29486a2Sdan#
452e8a537eeSdrh# EVIDENCE-OF: R-19836-11244 Example: X'53514C697465'
453c29486a2Sdan#
454c29486a2Sdando_execsql_test e_expr-10.4.1 { SELECT typeof(X'0123456789ABCDEF') } blob
455c29486a2Sdando_execsql_test e_expr-10.4.2 { SELECT typeof(x'0123456789ABCDEF') } blob
456c29486a2Sdando_execsql_test e_expr-10.4.3 { SELECT typeof(X'0123456789abcdef') } blob
457c29486a2Sdando_execsql_test e_expr-10.4.4 { SELECT typeof(x'0123456789abcdef') } blob
458c29486a2Sdando_execsql_test e_expr-10.4.5 { SELECT typeof(X'53514C697465')     } blob
459c29486a2Sdan
460c29486a2Sdan# EVIDENCE-OF: R-23914-51476 A literal value can also be the token
461c29486a2Sdan# "NULL".
462c7d6156dSdan#
463c29486a2Sdando_execsql_test e_expr-10.5.1 { SELECT NULL         } {{}}
464c29486a2Sdando_execsql_test e_expr-10.5.2 { SELECT typeof(NULL) } {null}
465c29486a2Sdan
466c7d6156dSdan#-------------------------------------------------------------------------
467c7d6156dSdan# Test statements related to bound parameters
468c7d6156dSdan#
469c7d6156dSdan
470c7d6156dSdanproc parameter_test {tn sql params result} {
471c7d6156dSdan  set stmt [sqlite3_prepare_v2 db $sql -1]
472c7d6156dSdan
473c7d6156dSdan  foreach {number name} $params {
474c7d6156dSdan    set nm [sqlite3_bind_parameter_name $stmt $number]
475c7d6156dSdan    do_test $tn.name.$number [list set {} $nm] $name
476c7d6156dSdan    sqlite3_bind_int $stmt $number [expr -1 * $number]
477c7d6156dSdan  }
478c7d6156dSdan
479c7d6156dSdan  sqlite3_step $stmt
480c7d6156dSdan
481c7d6156dSdan  set res [list]
482c7d6156dSdan  for {set i 0} {$i < [sqlite3_column_count $stmt]} {incr i} {
483c7d6156dSdan    lappend res [sqlite3_column_text $stmt $i]
484c7d6156dSdan  }
485c7d6156dSdan
486c7d6156dSdan  set rc [sqlite3_finalize $stmt]
487c7d6156dSdan  do_test $tn.rc [list set {} $rc] SQLITE_OK
488c7d6156dSdan  do_test $tn.res [list set {} $res] $result
489c7d6156dSdan}
490c7d6156dSdan
491c7d6156dSdan# EVIDENCE-OF: R-33509-39458 A question mark followed by a number NNN
492c7d6156dSdan# holds a spot for the NNN-th parameter. NNN must be between 1 and
493c7d6156dSdan# SQLITE_MAX_VARIABLE_NUMBER.
494c7d6156dSdan#
495c7d6156dSdanset mvn $SQLITE_MAX_VARIABLE_NUMBER
496c7d6156dSdanparameter_test e_expr-11.1 "
497c7d6156dSdan  SELECT ?1, ?123, ?$SQLITE_MAX_VARIABLE_NUMBER, ?123, ?4
498c7d6156dSdan"   "1 ?1  123 ?123 $mvn ?$mvn 4 ?4"   "-1 -123 -$mvn -123 -4"
499c7d6156dSdan
500c7d6156dSdanset errmsg "variable number must be between ?1 and ?$SQLITE_MAX_VARIABLE_NUMBER"
501c7d6156dSdanforeach {tn param_number} [list \
502c7d6156dSdan  2  0                                    \
503c7d6156dSdan  3  [expr $SQLITE_MAX_VARIABLE_NUMBER+1] \
504c7d6156dSdan  4  [expr $SQLITE_MAX_VARIABLE_NUMBER+2] \
505c7d6156dSdan  5  12345678903456789034567890234567890  \
506c7d6156dSdan  6  2147483648                           \
507c7d6156dSdan  7  2147483649                           \
508c7d6156dSdan  8  4294967296                           \
509c7d6156dSdan  9  4294967297                           \
510c7d6156dSdan  10 9223372036854775808                  \
511c7d6156dSdan  11 9223372036854775809                  \
512c7d6156dSdan  12 18446744073709551616                 \
513c7d6156dSdan  13 18446744073709551617                 \
514c7d6156dSdan] {
515c7d6156dSdan  do_catchsql_test e_expr-11.1.$tn "SELECT ?$param_number" [list 1 $errmsg]
516c7d6156dSdan}
517c7d6156dSdan
518c7d6156dSdan# EVIDENCE-OF: R-33670-36097 A question mark that is not followed by a
519c7d6156dSdan# number creates a parameter with a number one greater than the largest
520c7d6156dSdan# parameter number already assigned.
521c7d6156dSdan#
522c7d6156dSdan# EVIDENCE-OF: R-42938-07030 If this means the parameter number is
523c7d6156dSdan# greater than SQLITE_MAX_VARIABLE_NUMBER, it is an error.
524c7d6156dSdan#
525c7d6156dSdanparameter_test e_expr-11.2.1 "SELECT ?"          {1 {}}       -1
526c7d6156dSdanparameter_test e_expr-11.2.2 "SELECT ?, ?"       {1 {} 2 {}}  {-1 -2}
527c7d6156dSdanparameter_test e_expr-11.2.3 "SELECT ?5, ?"      {5 ?5 6 {}}  {-5 -6}
528c7d6156dSdanparameter_test e_expr-11.2.4 "SELECT ?, ?5"      {1 {} 5 ?5}  {-1 -5}
529c7d6156dSdanparameter_test e_expr-11.2.5 "SELECT ?, ?456, ?" {
530c7d6156dSdan  1 {} 456 ?456 457 {}
531c7d6156dSdan}  {-1 -456 -457}
532c7d6156dSdanparameter_test e_expr-11.2.5 "SELECT ?, ?456, ?4, ?" {
533c7d6156dSdan  1 {} 456 ?456 4 ?4 457 {}
534c7d6156dSdan}  {-1 -456 -4 -457}
535c7d6156dSdanforeach {tn sql} [list                           \
536c7d6156dSdan  1  "SELECT ?$mvn, ?"                           \
537c7d6156dSdan  2  "SELECT ?[expr $mvn-5], ?, ?, ?, ?, ?, ?"   \
538c7d6156dSdan  3  "SELECT ?[expr $mvn], ?5, ?6, ?"            \
539c7d6156dSdan] {
540c7d6156dSdan  do_catchsql_test e_expr-11.3.$tn $sql [list 1 {too many SQL variables}]
541c7d6156dSdan}
542c7d6156dSdan
543c7d6156dSdan# EVIDENCE-OF: R-11620-22743 A colon followed by an identifier name
544c7d6156dSdan# holds a spot for a named parameter with the name :AAAA.
545c7d6156dSdan#
546c7d6156dSdan# Identifiers in SQLite consist of alphanumeric, '_' and '$' characters,
547c7d6156dSdan# and any UTF characters with codepoints larger than 127 (non-ASCII
548c7d6156dSdan# characters).
549c7d6156dSdan#
550c7d6156dSdanparameter_test e_expr-11.2.1 {SELECT :AAAA}         {1 :AAAA}       -1
551c7d6156dSdanparameter_test e_expr-11.2.2 {SELECT :123}          {1 :123}        -1
552c7d6156dSdanparameter_test e_expr-11.2.3 {SELECT :__}           {1 :__}         -1
553c7d6156dSdanparameter_test e_expr-11.2.4 {SELECT :_$_}          {1 :_$_}        -1
554c7d6156dSdanparameter_test e_expr-11.2.5 "
555c7d6156dSdan  SELECT :\u0e40\u0e2d\u0e28\u0e02\u0e39\u0e40\u0e2d\u0e25
556c7d6156dSdan" "1 :\u0e40\u0e2d\u0e28\u0e02\u0e39\u0e40\u0e2d\u0e25" -1
557c7d6156dSdanparameter_test e_expr-11.2.6 "SELECT :\u0080" "1 :\u0080" -1
558c7d6156dSdan
559c7d6156dSdan# EVIDENCE-OF: R-49783-61279 An "at" sign works exactly like a colon,
560c7d6156dSdan# except that the name of the parameter created is @AAAA.
561c7d6156dSdan#
562c7d6156dSdanparameter_test e_expr-11.3.1 {SELECT @AAAA}         {1 @AAAA}       -1
563c7d6156dSdanparameter_test e_expr-11.3.2 {SELECT @123}          {1 @123}        -1
564c7d6156dSdanparameter_test e_expr-11.3.3 {SELECT @__}           {1 @__}         -1
565c7d6156dSdanparameter_test e_expr-11.3.4 {SELECT @_$_}          {1 @_$_}        -1
566c7d6156dSdanparameter_test e_expr-11.3.5 "
567c7d6156dSdan  SELECT @\u0e40\u0e2d\u0e28\u0e02\u0e39\u0e40\u0e2d\u0e25
568c7d6156dSdan" "1 @\u0e40\u0e2d\u0e28\u0e02\u0e39\u0e40\u0e2d\u0e25" -1
569c7d6156dSdanparameter_test e_expr-11.3.6 "SELECT @\u0080" "1 @\u0080" -1
570c7d6156dSdan
571c7d6156dSdan# EVIDENCE-OF: R-62610-51329 A dollar-sign followed by an identifier
572c7d6156dSdan# name also holds a spot for a named parameter with the name $AAAA.
573c7d6156dSdan#
574c7d6156dSdan# EVIDENCE-OF: R-55025-21042 The identifier name in this case can
575c7d6156dSdan# include one or more occurrences of "::" and a suffix enclosed in
576c7d6156dSdan# "(...)" containing any text at all.
577c7d6156dSdan#
578c7d6156dSdan# Note: Looks like an identifier cannot consist entirely of "::"
579c7d6156dSdan# characters or just a suffix. Also, the other named variable characters
580c7d6156dSdan# (: and @) work the same way internally. Why not just document it that way?
581c7d6156dSdan#
582c7d6156dSdanparameter_test e_expr-11.4.1 {SELECT $AAAA}         {1 $AAAA}       -1
583c7d6156dSdanparameter_test e_expr-11.4.2 {SELECT $123}          {1 $123}        -1
584c7d6156dSdanparameter_test e_expr-11.4.3 {SELECT $__}           {1 $__}         -1
585c7d6156dSdanparameter_test e_expr-11.4.4 {SELECT $_$_}          {1 $_$_}        -1
586c7d6156dSdanparameter_test e_expr-11.4.5 "
587c7d6156dSdan  SELECT \$\u0e40\u0e2d\u0e28\u0e02\u0e39\u0e40\u0e2d\u0e25
588c7d6156dSdan" "1 \$\u0e40\u0e2d\u0e28\u0e02\u0e39\u0e40\u0e2d\u0e25" -1
589c7d6156dSdanparameter_test e_expr-11.4.6 "SELECT \$\u0080" "1 \$\u0080" -1
590c7d6156dSdan
591c7d6156dSdanparameter_test e_expr-11.5.1 {SELECT $::::a(++--++)} {1 $::::a(++--++)} -1
592c7d6156dSdanparameter_test e_expr-11.5.2 {SELECT $::a()} {1 $::a()} -1
593c7d6156dSdanparameter_test e_expr-11.5.3 {SELECT $::1(::#$)} {1 $::1(::#$)} -1
594c7d6156dSdan
595c7d6156dSdan# EVIDENCE-OF: R-11370-04520 Named parameters are also numbered. The
596c7d6156dSdan# number assigned is one greater than the largest parameter number
597c7d6156dSdan# already assigned.
598c7d6156dSdan#
599c7d6156dSdan# EVIDENCE-OF: R-42620-22184 If this means the parameter would be
600c7d6156dSdan# assigned a number greater than SQLITE_MAX_VARIABLE_NUMBER, it is an
601c7d6156dSdan# error.
602c7d6156dSdan#
603c7d6156dSdanparameter_test e_expr-11.6.1 "SELECT ?, @abc"    {1 {} 2 @abc} {-1 -2}
604c7d6156dSdanparameter_test e_expr-11.6.2 "SELECT ?123, :a1"  {123 ?123 124 :a1} {-123 -124}
605c7d6156dSdanparameter_test e_expr-11.6.3 {SELECT $a, ?8, ?, $b, ?2, $c} {
606c7d6156dSdan  1 $a 8 ?8 9 {} 10 $b 2 ?2 11 $c
607c7d6156dSdan} {-1 -8 -9 -10 -2 -11}
608c7d6156dSdanforeach {tn sql} [list                           \
609c7d6156dSdan  1  "SELECT ?$mvn, \$::a"                       \
610c7d6156dSdan  2  "SELECT ?$mvn, ?4, @a1"                     \
611c7d6156dSdan  3  "SELECT ?[expr $mvn-2], :bag, @123, \$x"    \
612c7d6156dSdan] {
613c7d6156dSdan  do_catchsql_test e_expr-11.7.$tn $sql [list 1 {too many SQL variables}]
614c7d6156dSdan}
615c7d6156dSdan
6161afca9b7Sdan# EVIDENCE-OF: R-14068-49671 Parameters that are not assigned values
6171afca9b7Sdan# using sqlite3_bind() are treated as NULL.
6181afca9b7Sdan#
6191afca9b7Sdando_test e_expr-11.7.1 {
6201afca9b7Sdan  set stmt [sqlite3_prepare_v2 db { SELECT ?, :a, @b, $d } -1]
6211afca9b7Sdan  sqlite3_step $stmt
6221afca9b7Sdan
6231afca9b7Sdan  list [sqlite3_column_type $stmt 0] \
6241afca9b7Sdan       [sqlite3_column_type $stmt 1] \
6251afca9b7Sdan       [sqlite3_column_type $stmt 2] \
6261afca9b7Sdan       [sqlite3_column_type $stmt 3]
6271afca9b7Sdan} {NULL NULL NULL NULL}
6281afca9b7Sdando_test e_expr-11.7.1 { sqlite3_finalize $stmt } SQLITE_OK
6291afca9b7Sdan
630994e9403Sdan#-------------------------------------------------------------------------
631994e9403Sdan# "Test" the syntax diagrams in lang_expr.html.
632994e9403Sdan#
63339759747Sdrh# -- syntax diagram signed-number
634994e9403Sdan#
635994e9403Sdando_execsql_test e_expr-12.1.1 { SELECT 0, +0, -0 } {0 0 0}
636994e9403Sdando_execsql_test e_expr-12.1.2 { SELECT 1, +1, -1 } {1 1 -1}
637994e9403Sdando_execsql_test e_expr-12.1.3 { SELECT 2, +2, -2 } {2 2 -2}
638994e9403Sdando_execsql_test e_expr-12.1.4 {
639994e9403Sdan  SELECT 1.4, +1.4, -1.4
640994e9403Sdan} {1.4 1.4 -1.4}
641994e9403Sdando_execsql_test e_expr-12.1.5 {
642994e9403Sdan  SELECT 1.5e+5, +1.5e+5, -1.5e+5
643994e9403Sdan} {150000.0 150000.0 -150000.0}
644994e9403Sdando_execsql_test e_expr-12.1.6 {
645994e9403Sdan  SELECT 0.0001, +0.0001, -0.0001
646994e9403Sdan} {0.0001 0.0001 -0.0001}
647994e9403Sdan
64839759747Sdrh# -- syntax diagram literal-value
649994e9403Sdan#
650994e9403Sdanset sqlite_current_time 1
651994e9403Sdando_execsql_test e_expr-12.2.1 {SELECT 123}               {123}
652994e9403Sdando_execsql_test e_expr-12.2.2 {SELECT 123.4e05}          {12340000.0}
653994e9403Sdando_execsql_test e_expr-12.2.3 {SELECT 'abcde'}           {abcde}
654994e9403Sdando_execsql_test e_expr-12.2.4 {SELECT X'414243'}         {ABC}
655994e9403Sdando_execsql_test e_expr-12.2.5 {SELECT NULL}              {{}}
656994e9403Sdando_execsql_test e_expr-12.2.6 {SELECT CURRENT_TIME}      {00:00:01}
657994e9403Sdando_execsql_test e_expr-12.2.7 {SELECT CURRENT_DATE}      {1970-01-01}
658994e9403Sdando_execsql_test e_expr-12.2.8 {SELECT CURRENT_TIMESTAMP} {{1970-01-01 00:00:01}}
659994e9403Sdanset sqlite_current_time 0
660994e9403Sdan
66139759747Sdrh# -- syntax diagram expr
662994e9403Sdan#
663fda06befSmistachkinforcedelete test.db2
664994e9403Sdanexecsql {
665994e9403Sdan  ATTACH 'test.db2' AS dbname;
666994e9403Sdan  CREATE TABLE dbname.tblname(cname);
667994e9403Sdan}
668994e9403Sdan
669994e9403Sdanproc glob {args} {return 1}
670994e9403Sdandb function glob glob
671994e9403Sdandb function match glob
672994e9403Sdandb function regexp glob
673994e9403Sdan
674994e9403Sdanforeach {tn expr} {
675994e9403Sdan  1 123
676994e9403Sdan  2 123.4e05
677994e9403Sdan  3 'abcde'
678994e9403Sdan  4 X'414243'
679994e9403Sdan  5 NULL
680994e9403Sdan  6 CURRENT_TIME
681994e9403Sdan  7 CURRENT_DATE
682994e9403Sdan  8 CURRENT_TIMESTAMP
683994e9403Sdan
684994e9403Sdan  9 ?
685994e9403Sdan 10 ?123
686994e9403Sdan 11 @hello
687994e9403Sdan 12 :world
688994e9403Sdan 13 $tcl
689994e9403Sdan 14 $tcl(array)
690994e9403Sdan
691994e9403Sdan  15 cname
692994e9403Sdan  16 tblname.cname
693994e9403Sdan  17 dbname.tblname.cname
694994e9403Sdan
695994e9403Sdan  18 "+ EXPR"
696994e9403Sdan  19 "- EXPR"
697994e9403Sdan  20 "NOT EXPR"
698994e9403Sdan  21 "~ EXPR"
699994e9403Sdan
700994e9403Sdan  22 "EXPR1 || EXPR2"
701994e9403Sdan  23 "EXPR1 * EXPR2"
702994e9403Sdan  24 "EXPR1 / EXPR2"
703994e9403Sdan  25 "EXPR1 % EXPR2"
704994e9403Sdan  26 "EXPR1 + EXPR2"
705994e9403Sdan  27 "EXPR1 - EXPR2"
706994e9403Sdan  28 "EXPR1 << EXPR2"
707994e9403Sdan  29 "EXPR1 >> EXPR2"
708994e9403Sdan  30 "EXPR1 & EXPR2"
709994e9403Sdan  31 "EXPR1 | EXPR2"
710994e9403Sdan  32 "EXPR1 < EXPR2"
711994e9403Sdan  33 "EXPR1 <= EXPR2"
712994e9403Sdan  34 "EXPR1 > EXPR2"
713994e9403Sdan  35 "EXPR1 >= EXPR2"
714994e9403Sdan  36 "EXPR1 = EXPR2"
715994e9403Sdan  37 "EXPR1 == EXPR2"
716994e9403Sdan  38 "EXPR1 != EXPR2"
717994e9403Sdan  39 "EXPR1 <> EXPR2"
718994e9403Sdan  40 "EXPR1 IS EXPR2"
719994e9403Sdan  41 "EXPR1 IS NOT EXPR2"
720994e9403Sdan  42 "EXPR1 AND EXPR2"
721994e9403Sdan  43 "EXPR1 OR EXPR2"
722994e9403Sdan
723994e9403Sdan  44 "count(*)"
724994e9403Sdan  45 "count(DISTINCT EXPR)"
725994e9403Sdan  46 "substr(EXPR, 10, 20)"
726994e9403Sdan  47 "changes()"
727994e9403Sdan
728994e9403Sdan  48 "( EXPR )"
729994e9403Sdan
730994e9403Sdan  49 "CAST ( EXPR AS integer )"
731994e9403Sdan  50 "CAST ( EXPR AS 'abcd' )"
732994e9403Sdan  51 "CAST ( EXPR AS 'ab$ $cd' )"
733994e9403Sdan
734994e9403Sdan  52 "EXPR COLLATE nocase"
735994e9403Sdan  53 "EXPR COLLATE binary"
736994e9403Sdan
737994e9403Sdan  54 "EXPR1 LIKE EXPR2"
738994e9403Sdan  55 "EXPR1 LIKE EXPR2 ESCAPE EXPR"
739994e9403Sdan  56 "EXPR1 GLOB EXPR2"
740994e9403Sdan  57 "EXPR1 GLOB EXPR2 ESCAPE EXPR"
741994e9403Sdan  58 "EXPR1 REGEXP EXPR2"
742994e9403Sdan  59 "EXPR1 REGEXP EXPR2 ESCAPE EXPR"
743994e9403Sdan  60 "EXPR1 MATCH EXPR2"
744994e9403Sdan  61 "EXPR1 MATCH EXPR2 ESCAPE EXPR"
745994e9403Sdan  62 "EXPR1 NOT LIKE EXPR2"
746994e9403Sdan  63 "EXPR1 NOT LIKE EXPR2 ESCAPE EXPR"
747994e9403Sdan  64 "EXPR1 NOT GLOB EXPR2"
748994e9403Sdan  65 "EXPR1 NOT GLOB EXPR2 ESCAPE EXPR"
749994e9403Sdan  66 "EXPR1 NOT REGEXP EXPR2"
750994e9403Sdan  67 "EXPR1 NOT REGEXP EXPR2 ESCAPE EXPR"
751994e9403Sdan  68 "EXPR1 NOT MATCH EXPR2"
752994e9403Sdan  69 "EXPR1 NOT MATCH EXPR2 ESCAPE EXPR"
753994e9403Sdan
754994e9403Sdan  70 "EXPR ISNULL"
755994e9403Sdan  71 "EXPR NOTNULL"
756994e9403Sdan  72 "EXPR NOT NULL"
757994e9403Sdan
758994e9403Sdan  73 "EXPR1 IS EXPR2"
759994e9403Sdan  74 "EXPR1 IS NOT EXPR2"
760994e9403Sdan
761994e9403Sdan  75 "EXPR NOT BETWEEN EXPR1 AND EXPR2"
762994e9403Sdan  76 "EXPR BETWEEN EXPR1 AND EXPR2"
763994e9403Sdan
764994e9403Sdan  77 "EXPR NOT IN (SELECT cname FROM tblname)"
765994e9403Sdan  78 "EXPR NOT IN (1)"
766994e9403Sdan  79 "EXPR NOT IN (1, 2, 3)"
767994e9403Sdan  80 "EXPR NOT IN tblname"
768994e9403Sdan  81 "EXPR NOT IN dbname.tblname"
769994e9403Sdan  82 "EXPR IN (SELECT cname FROM tblname)"
770994e9403Sdan  83 "EXPR IN (1)"
771994e9403Sdan  84 "EXPR IN (1, 2, 3)"
772994e9403Sdan  85 "EXPR IN tblname"
773994e9403Sdan  86 "EXPR IN dbname.tblname"
774994e9403Sdan
775994e9403Sdan  87 "EXISTS (SELECT cname FROM tblname)"
776994e9403Sdan  88 "NOT EXISTS (SELECT cname FROM tblname)"
777994e9403Sdan
778994e9403Sdan  89 "CASE EXPR WHEN EXPR1 THEN EXPR2 ELSE EXPR END"
779994e9403Sdan  90 "CASE EXPR WHEN EXPR1 THEN EXPR2 END"
780994e9403Sdan  91 "CASE EXPR WHEN EXPR1 THEN EXPR2 WHEN EXPR THEN EXPR1 ELSE EXPR2 END"
781994e9403Sdan  92 "CASE EXPR WHEN EXPR1 THEN EXPR2 WHEN EXPR THEN EXPR1 END"
782994e9403Sdan  93 "CASE WHEN EXPR1 THEN EXPR2 ELSE EXPR END"
783994e9403Sdan  94 "CASE WHEN EXPR1 THEN EXPR2 END"
784994e9403Sdan  95 "CASE WHEN EXPR1 THEN EXPR2 WHEN EXPR THEN EXPR1 ELSE EXPR2 END"
785994e9403Sdan  96 "CASE WHEN EXPR1 THEN EXPR2 WHEN EXPR THEN EXPR1 END"
786994e9403Sdan} {
787994e9403Sdan
788994e9403Sdan  # If the expression string being parsed contains "EXPR2", then replace
789994e9403Sdan  # string "EXPR1" and "EXPR2" with arbitrary SQL expressions. If it
790994e9403Sdan  # contains "EXPR", then replace EXPR with an arbitrary SQL expression.
791994e9403Sdan  #
792994e9403Sdan  set elist [list $expr]
793994e9403Sdan  if {[string match *EXPR2* $expr]} {
794994e9403Sdan    set elist [list]
795994e9403Sdan    foreach {e1 e2} { cname "34+22" } {
796994e9403Sdan      lappend elist [string map [list EXPR1 $e1 EXPR2 $e2] $expr]
797994e9403Sdan    }
798994e9403Sdan  }
799994e9403Sdan  if {[string match *EXPR* $expr]} {
800994e9403Sdan    set elist2 [list]
801994e9403Sdan    foreach el $elist {
802994e9403Sdan      foreach e { cname "34+22" } {
803994e9403Sdan        lappend elist2 [string map [list EXPR $e] $el]
804994e9403Sdan      }
805994e9403Sdan    }
806994e9403Sdan    set elist $elist2
807994e9403Sdan  }
808994e9403Sdan
809994e9403Sdan  set x 0
810994e9403Sdan  foreach e $elist {
811994e9403Sdan    incr x
812994e9403Sdan    do_test e_expr-12.3.$tn.$x {
813994e9403Sdan      set rc [catch { execsql "SELECT $e FROM tblname" } msg]
814994e9403Sdan    } {0}
815994e9403Sdan  }
816994e9403Sdan}
817994e9403Sdan
81839759747Sdrh# -- syntax diagram raise-function
819994e9403Sdan#
820994e9403Sdanforeach {tn raiseexpr} {
821994e9403Sdan  1 "RAISE(IGNORE)"
822994e9403Sdan  2 "RAISE(ROLLBACK, 'error message')"
823994e9403Sdan  3 "RAISE(ABORT, 'error message')"
824994e9403Sdan  4 "RAISE(FAIL, 'error message')"
825994e9403Sdan} {
826994e9403Sdan  do_execsql_test e_expr-12.4.$tn "
827994e9403Sdan    CREATE TRIGGER dbname.tr$tn BEFORE DELETE ON tblname BEGIN
828994e9403Sdan      SELECT $raiseexpr ;
829994e9403Sdan    END;
830994e9403Sdan  " {}
831994e9403Sdan}
832994e9403Sdan
83373625ec3Sdan#-------------------------------------------------------------------------
83473625ec3Sdan# Test the statements related to the BETWEEN operator.
83573625ec3Sdan#
83673625ec3Sdan# EVIDENCE-OF: R-40079-54503 The BETWEEN operator is logically
83773625ec3Sdan# equivalent to a pair of comparisons. "x BETWEEN y AND z" is equivalent
83873625ec3Sdan# to "x>=y AND x<=z" except that with BETWEEN, the x expression is
83973625ec3Sdan# only evaluated once.
84073625ec3Sdan#
84173625ec3Sdandb func x x
84273625ec3Sdanproc x {} { incr ::xcount ; return [expr $::x] }
84373625ec3Sdanforeach {tn x expr res nEval} {
84473625ec3Sdan  1  10  "x() >= 5 AND x() <= 15"  1  2
84573625ec3Sdan  2  10  "x() BETWEEN 5 AND 15"    1  1
84673625ec3Sdan
84773625ec3Sdan  3   5  "x() >= 5 AND x() <= 5"   1  2
84873625ec3Sdan  4   5  "x() BETWEEN 5 AND 5"     1  1
84912abf408Sdrh
85012abf408Sdrh  5   9  "(x(),8) >= (9,7) AND (x(),8)<=(9,10)"  1 2
85112abf408Sdrh  6   9  "(x(),8) BETWEEN (9,7) AND (9,10)"      1 1
85273625ec3Sdan} {
85373625ec3Sdan  do_test e_expr-13.1.$tn {
85473625ec3Sdan    set ::xcount 0
85573625ec3Sdan    set a [execsql "SELECT $expr"]
85673625ec3Sdan    list $::xcount $a
85773625ec3Sdan  } [list $nEval $res]
85873625ec3Sdan}
85973625ec3Sdan
860c0bd26a2Sdrh# X-EVIDENCE-OF: R-05155-34454 The precedence of the BETWEEN operator is
86173625ec3Sdan# the same as the precedence as operators == and != and LIKE and groups
86273625ec3Sdan# left to right.
86373625ec3Sdan#
86473625ec3Sdan# Therefore, BETWEEN groups more tightly than operator "AND", but less
86573625ec3Sdan# so than "<".
86673625ec3Sdan#
86773625ec3Sdando_execsql_test e_expr-13.2.1  { SELECT 1 == 10 BETWEEN 0 AND 2   }  1
86873625ec3Sdando_execsql_test e_expr-13.2.2  { SELECT (1 == 10) BETWEEN 0 AND 2 }  1
86973625ec3Sdando_execsql_test e_expr-13.2.3  { SELECT 1 == (10 BETWEEN 0 AND 2) }  0
87073625ec3Sdando_execsql_test e_expr-13.2.4  { SELECT  6 BETWEEN 4 AND 8 == 1 }    1
87173625ec3Sdando_execsql_test e_expr-13.2.5  { SELECT (6 BETWEEN 4 AND 8) == 1 }   1
87273625ec3Sdando_execsql_test e_expr-13.2.6  { SELECT  6 BETWEEN 4 AND (8 == 1) }  0
87373625ec3Sdan
87473625ec3Sdando_execsql_test e_expr-13.2.7  { SELECT  5 BETWEEN 0 AND 0  != 1 }   1
87573625ec3Sdando_execsql_test e_expr-13.2.8  { SELECT (5 BETWEEN 0 AND 0) != 1 }   1
87673625ec3Sdando_execsql_test e_expr-13.2.9  { SELECT  5 BETWEEN 0 AND (0 != 1) }  0
87773625ec3Sdando_execsql_test e_expr-13.2.10 { SELECT  1 != 0  BETWEEN 0 AND 2  }  1
87873625ec3Sdando_execsql_test e_expr-13.2.11 { SELECT (1 != 0) BETWEEN 0 AND 2  }  1
87973625ec3Sdando_execsql_test e_expr-13.2.12 { SELECT  1 != (0 BETWEEN 0 AND 2) }  0
88073625ec3Sdan
88173625ec3Sdando_execsql_test e_expr-13.2.13 { SELECT 1 LIKE 10 BETWEEN 0 AND 2   }  1
88273625ec3Sdando_execsql_test e_expr-13.2.14 { SELECT (1 LIKE 10) BETWEEN 0 AND 2 }  1
88373625ec3Sdando_execsql_test e_expr-13.2.15 { SELECT 1 LIKE (10 BETWEEN 0 AND 2) }  0
88473625ec3Sdando_execsql_test e_expr-13.2.16 { SELECT  6 BETWEEN 4 AND 8 LIKE 1   }  1
88573625ec3Sdando_execsql_test e_expr-13.2.17 { SELECT (6 BETWEEN 4 AND 8) LIKE 1  }  1
88673625ec3Sdando_execsql_test e_expr-13.2.18 { SELECT  6 BETWEEN 4 AND (8 LIKE 1) }  0
88773625ec3Sdan
88873625ec3Sdando_execsql_test e_expr-13.2.19 { SELECT 0 AND 0 BETWEEN 0 AND 1   } 0
88973625ec3Sdando_execsql_test e_expr-13.2.20 { SELECT 0 AND (0 BETWEEN 0 AND 1) } 0
89073625ec3Sdando_execsql_test e_expr-13.2.21 { SELECT (0 AND 0) BETWEEN 0 AND 1 } 1
89173625ec3Sdando_execsql_test e_expr-13.2.22 { SELECT 0 BETWEEN -1 AND 1 AND 0   } 0
89273625ec3Sdando_execsql_test e_expr-13.2.23 { SELECT (0 BETWEEN -1 AND 1) AND 0 } 0
89373625ec3Sdando_execsql_test e_expr-13.2.24 { SELECT 0 BETWEEN -1 AND (1 AND 0) } 1
89473625ec3Sdan
89573625ec3Sdando_execsql_test e_expr-13.2.25 { SELECT 2 < 3 BETWEEN 0 AND 1   } 1
89673625ec3Sdando_execsql_test e_expr-13.2.26 { SELECT (2 < 3) BETWEEN 0 AND 1 } 1
89773625ec3Sdando_execsql_test e_expr-13.2.27 { SELECT 2 < (3 BETWEEN 0 AND 1) } 0
89873625ec3Sdando_execsql_test e_expr-13.2.28 { SELECT 2 BETWEEN 1 AND 2 < 3    } 0
89973625ec3Sdando_execsql_test e_expr-13.2.29 { SELECT 2 BETWEEN 1 AND (2 < 3)  } 0
90073625ec3Sdando_execsql_test e_expr-13.2.30 { SELECT (2 BETWEEN 1 AND 2) < 3  } 1
901f5d3df40Sdan
902f5d3df40Sdan#-------------------------------------------------------------------------
903f5d3df40Sdan# Test the statements related to the LIKE and GLOB operators.
904f5d3df40Sdan#
905f5d3df40Sdan# EVIDENCE-OF: R-16584-60189 The LIKE operator does a pattern matching
906f5d3df40Sdan# comparison.
907f5d3df40Sdan#
908f5d3df40Sdan# EVIDENCE-OF: R-11295-04657 The operand to the right of the LIKE
909f5d3df40Sdan# operator contains the pattern and the left hand operand contains the
910f5d3df40Sdan# string to match against the pattern.
911f5d3df40Sdan#
912f5d3df40Sdando_execsql_test e_expr-14.1.1 { SELECT 'abc%' LIKE 'abcde' } 0
913f5d3df40Sdando_execsql_test e_expr-14.1.2 { SELECT 'abcde' LIKE 'abc%' } 1
914f5d3df40Sdan
915f5d3df40Sdan# EVIDENCE-OF: R-55406-38524 A percent symbol ("%") in the LIKE pattern
916f5d3df40Sdan# matches any sequence of zero or more characters in the string.
917f5d3df40Sdan#
918f5d3df40Sdando_execsql_test e_expr-14.2.1 { SELECT 'abde'    LIKE 'ab%de' } 1
919f5d3df40Sdando_execsql_test e_expr-14.2.2 { SELECT 'abXde'   LIKE 'ab%de' } 1
920f5d3df40Sdando_execsql_test e_expr-14.2.3 { SELECT 'abABCde' LIKE 'ab%de' } 1
921f5d3df40Sdan
922f5d3df40Sdan# EVIDENCE-OF: R-30433-25443 An underscore ("_") in the LIKE pattern
923f5d3df40Sdan# matches any single character in the string.
924f5d3df40Sdan#
925f5d3df40Sdando_execsql_test e_expr-14.3.1 { SELECT 'abde'    LIKE 'ab_de' } 0
926f5d3df40Sdando_execsql_test e_expr-14.3.2 { SELECT 'abXde'   LIKE 'ab_de' } 1
927f5d3df40Sdando_execsql_test e_expr-14.3.3 { SELECT 'abABCde' LIKE 'ab_de' } 0
928f5d3df40Sdan
929f5d3df40Sdan# EVIDENCE-OF: R-59007-20454 Any other character matches itself or its
930f5d3df40Sdan# lower/upper case equivalent (i.e. case-insensitive matching).
931f5d3df40Sdan#
932f5d3df40Sdando_execsql_test e_expr-14.4.1 { SELECT 'abc' LIKE 'aBc' } 1
933f5d3df40Sdando_execsql_test e_expr-14.4.2 { SELECT 'aBc' LIKE 'aBc' } 1
934f5d3df40Sdando_execsql_test e_expr-14.4.3 { SELECT 'ac'  LIKE 'aBc' } 0
935f5d3df40Sdan
936f5d3df40Sdan# EVIDENCE-OF: R-23648-58527 SQLite only understands upper/lower case
937f5d3df40Sdan# for ASCII characters by default.
938f5d3df40Sdan#
939f5d3df40Sdan# EVIDENCE-OF: R-04532-11527 The LIKE operator is case sensitive by
940f5d3df40Sdan# default for unicode characters that are beyond the ASCII range.
941f5d3df40Sdan#
942f5d3df40Sdan# EVIDENCE-OF: R-44381-11669 the expression
943f5d3df40Sdan# 'a'&nbsp;LIKE&nbsp;'A' is TRUE but
944f5d3df40Sdan# '&aelig;'&nbsp;LIKE&nbsp;'&AElig;' is FALSE.
945f5d3df40Sdan#
9466bd2c735Sdan#   The restriction to ASCII characters does not apply if the ICU
9476bd2c735Sdan#   library is compiled in. When ICU is enabled SQLite does not act
9486bd2c735Sdan#   as it does "by default".
9496bd2c735Sdan#
950f5d3df40Sdando_execsql_test e_expr-14.5.1 { SELECT 'A' LIKE 'a'         } 1
9516bd2c735Sdanifcapable !icu {
952f5d3df40Sdan  do_execsql_test e_expr-14.5.2 "SELECT '\u00c6' LIKE '\u00e6'" 0
9536bd2c735Sdan}
954f5d3df40Sdan
955f5d3df40Sdan# EVIDENCE-OF: R-56683-13731 If the optional ESCAPE clause is present,
956f5d3df40Sdan# then the expression following the ESCAPE keyword must evaluate to a
957f5d3df40Sdan# string consisting of a single character.
958f5d3df40Sdan#
959f5d3df40Sdando_catchsql_test e_expr-14.6.1 {
960f5d3df40Sdan  SELECT 'A' LIKE 'a' ESCAPE '12'
961f5d3df40Sdan} {1 {ESCAPE expression must be a single character}}
962f5d3df40Sdando_catchsql_test e_expr-14.6.2 {
963f5d3df40Sdan  SELECT 'A' LIKE 'a' ESCAPE ''
964f5d3df40Sdan} {1 {ESCAPE expression must be a single character}}
965f5d3df40Sdando_catchsql_test e_expr-14.6.3 { SELECT 'A' LIKE 'a' ESCAPE 'x' }    {0 1}
966f5d3df40Sdando_catchsql_test e_expr-14.6.4 "SELECT 'A' LIKE 'a' ESCAPE '\u00e6'" {0 1}
967f5d3df40Sdan
968f5d3df40Sdan# EVIDENCE-OF: R-02045-23762 This character may be used in the LIKE
969f5d3df40Sdan# pattern to include literal percent or underscore characters.
970f5d3df40Sdan#
971f5d3df40Sdan# EVIDENCE-OF: R-13345-31830 The escape character followed by a percent
972f5d3df40Sdan# symbol (%), underscore (_), or a second instance of the escape
973f5d3df40Sdan# character itself matches a literal percent symbol, underscore, or a
974f5d3df40Sdan# single escape character, respectively.
975f5d3df40Sdan#
976f5d3df40Sdando_execsql_test e_expr-14.7.1  { SELECT 'abc%'  LIKE 'abcX%' ESCAPE 'X' } 1
977f5d3df40Sdando_execsql_test e_expr-14.7.2  { SELECT 'abc5'  LIKE 'abcX%' ESCAPE 'X' } 0
978f5d3df40Sdando_execsql_test e_expr-14.7.3  { SELECT 'abc'   LIKE 'abcX%' ESCAPE 'X' } 0
979f5d3df40Sdando_execsql_test e_expr-14.7.4  { SELECT 'abcX%' LIKE 'abcX%' ESCAPE 'X' } 0
980f5d3df40Sdando_execsql_test e_expr-14.7.5  { SELECT 'abc%%' LIKE 'abcX%' ESCAPE 'X' } 0
981f5d3df40Sdan
982f5d3df40Sdando_execsql_test e_expr-14.7.6  { SELECT 'abc_'  LIKE 'abcX_' ESCAPE 'X' } 1
983f5d3df40Sdando_execsql_test e_expr-14.7.7  { SELECT 'abc5'  LIKE 'abcX_' ESCAPE 'X' } 0
984f5d3df40Sdando_execsql_test e_expr-14.7.8  { SELECT 'abc'   LIKE 'abcX_' ESCAPE 'X' } 0
985f5d3df40Sdando_execsql_test e_expr-14.7.9  { SELECT 'abcX_' LIKE 'abcX_' ESCAPE 'X' } 0
986f5d3df40Sdando_execsql_test e_expr-14.7.10 { SELECT 'abc__' LIKE 'abcX_' ESCAPE 'X' } 0
987f5d3df40Sdan
988f5d3df40Sdando_execsql_test e_expr-14.7.11 { SELECT 'abcX'  LIKE 'abcXX' ESCAPE 'X' } 1
989f5d3df40Sdando_execsql_test e_expr-14.7.12 { SELECT 'abc5'  LIKE 'abcXX' ESCAPE 'X' } 0
990f5d3df40Sdando_execsql_test e_expr-14.7.13 { SELECT 'abc'   LIKE 'abcXX' ESCAPE 'X' } 0
991f5d3df40Sdando_execsql_test e_expr-14.7.14 { SELECT 'abcXX' LIKE 'abcXX' ESCAPE 'X' } 0
992f5d3df40Sdan
993f5d3df40Sdan# EVIDENCE-OF: R-51359-17496 The infix LIKE operator is implemented by
994f5d3df40Sdan# calling the application-defined SQL functions like(Y,X) or like(Y,X,Z).
995f5d3df40Sdan#
996f5d3df40Sdanproc likefunc {args} {
997f5d3df40Sdan  eval lappend ::likeargs $args
998f5d3df40Sdan  return 1
999f5d3df40Sdan}
10006bd2c735Sdandb func like -argcount 2 likefunc
10016bd2c735Sdandb func like -argcount 3 likefunc
1002f5d3df40Sdanset ::likeargs [list]
1003f5d3df40Sdando_execsql_test e_expr-15.1.1 { SELECT 'abc' LIKE 'def' } 1
1004f5d3df40Sdando_test         e_expr-15.1.2 { set likeargs } {def abc}
1005f5d3df40Sdanset ::likeargs [list]
1006f5d3df40Sdando_execsql_test e_expr-15.1.3 { SELECT 'abc' LIKE 'def' ESCAPE 'X' } 1
1007f5d3df40Sdando_test         e_expr-15.1.4 { set likeargs } {def abc X}
1008f5d3df40Sdandb close
1009f5d3df40Sdansqlite3 db test.db
1010f5d3df40Sdan
1011f5d3df40Sdan# EVIDENCE-OF: R-22868-25880 The LIKE operator can be made case
1012f5d3df40Sdan# sensitive using the case_sensitive_like pragma.
1013f5d3df40Sdan#
1014f5d3df40Sdando_execsql_test e_expr-16.1.1  { SELECT 'abcxyz' LIKE 'ABC%' } 1
1015ea5c040fSdrhdo_execsql_test e_expr-16.1.1b { SELECT 'abc%xyz' LIKE 'ABC\%x%' ESCAPE '\' } 1
1016f5d3df40Sdando_execsql_test e_expr-16.1.2  { PRAGMA case_sensitive_like = 1 } {}
1017f5d3df40Sdando_execsql_test e_expr-16.1.3  { SELECT 'abcxyz' LIKE 'ABC%' } 0
1018ea5c040fSdrhdo_execsql_test e_expr-16.1.3b { SELECT 'abc%xyz' LIKE 'ABC\%X%' ESCAPE '\' } 0
1019f5d3df40Sdando_execsql_test e_expr-16.1.4  { SELECT 'ABCxyz' LIKE 'ABC%' } 1
1020ea5c040fSdrhdo_execsql_test e_expr-16.1.4b { SELECT 'ABC%xyz' LIKE 'ABC\%x%' ESCAPE '\' } 1
1021f5d3df40Sdando_execsql_test e_expr-16.1.5  { PRAGMA case_sensitive_like = 0 } {}
1022f5d3df40Sdando_execsql_test e_expr-16.1.6  { SELECT 'abcxyz' LIKE 'ABC%' } 1
1023ea5c040fSdrhdo_execsql_test e_expr-16.1.6b { SELECT 'abc%xyz' LIKE 'ABC\%X%' ESCAPE '\' } 1
1024f5d3df40Sdando_execsql_test e_expr-16.1.7  { SELECT 'ABCxyz' LIKE 'ABC%' } 1
1025ea5c040fSdrhdo_execsql_test e_expr-16.1.7b { SELECT 'ABC%xyz' LIKE 'ABC\%X%' ESCAPE '\' } 1
1026f5d3df40Sdan
1027f5d3df40Sdan# EVIDENCE-OF: R-52087-12043 The GLOB operator is similar to LIKE but
1028f5d3df40Sdan# uses the Unix file globbing syntax for its wildcards.
1029f5d3df40Sdan#
1030f5d3df40Sdan# EVIDENCE-OF: R-09813-17279 Also, GLOB is case sensitive, unlike LIKE.
1031f5d3df40Sdan#
1032f5d3df40Sdando_execsql_test e_expr-17.1.1 { SELECT 'abcxyz' GLOB 'abc%' } 0
1033f5d3df40Sdando_execsql_test e_expr-17.1.2 { SELECT 'abcxyz' GLOB 'abc*' } 1
1034f5d3df40Sdando_execsql_test e_expr-17.1.3 { SELECT 'abcxyz' GLOB 'abc___' } 0
1035f5d3df40Sdando_execsql_test e_expr-17.1.4 { SELECT 'abcxyz' GLOB 'abc???' } 1
1036f5d3df40Sdan
1037f5d3df40Sdando_execsql_test e_expr-17.1.5 { SELECT 'abcxyz' GLOB 'abc*' } 1
1038f5d3df40Sdando_execsql_test e_expr-17.1.6 { SELECT 'ABCxyz' GLOB 'abc*' } 0
1039f5d3df40Sdando_execsql_test e_expr-17.1.7 { SELECT 'abcxyz' GLOB 'ABC*' } 0
1040f5d3df40Sdan
1041f5d3df40Sdan# EVIDENCE-OF: R-39616-20555 Both GLOB and LIKE may be preceded by the
1042f5d3df40Sdan# NOT keyword to invert the sense of the test.
1043f5d3df40Sdan#
1044f5d3df40Sdando_execsql_test e_expr-17.2.1 { SELECT 'abcxyz' NOT GLOB 'ABC*' } 1
1045f5d3df40Sdando_execsql_test e_expr-17.2.2 { SELECT 'abcxyz' NOT GLOB 'abc*' } 0
1046f5d3df40Sdando_execsql_test e_expr-17.2.3 { SELECT 'abcxyz' NOT LIKE 'ABC%' } 0
1047f5d3df40Sdando_execsql_test e_expr-17.2.4 { SELECT 'abcxyz' NOT LIKE 'abc%' } 0
1048f5d3df40Sdando_execsql_test e_expr-17.2.5 { SELECT 'abdxyz' NOT LIKE 'abc%' } 1
1049f5d3df40Sdan
1050f5d3df40Sdandb nullvalue null
1051f5d3df40Sdando_execsql_test e_expr-17.2.6 { SELECT 'abcxyz' NOT GLOB NULL } null
1052f5d3df40Sdando_execsql_test e_expr-17.2.7 { SELECT 'abcxyz' NOT LIKE NULL } null
1053f5d3df40Sdando_execsql_test e_expr-17.2.8 { SELECT NULL NOT GLOB 'abc*' } null
1054f5d3df40Sdando_execsql_test e_expr-17.2.9 { SELECT NULL NOT LIKE 'ABC%' } null
1055f5d3df40Sdandb nullvalue {}
1056f5d3df40Sdan
1057f5d3df40Sdan# EVIDENCE-OF: R-39414-35489 The infix GLOB operator is implemented by
1058f5d3df40Sdan# calling the function glob(Y,X) and can be modified by overriding that
1059f5d3df40Sdan# function.
1060f5d3df40Sdanproc globfunc {args} {
1061f5d3df40Sdan  eval lappend ::globargs $args
1062f5d3df40Sdan  return 1
1063f5d3df40Sdan}
1064f5d3df40Sdandb func glob -argcount 2 globfunc
1065f5d3df40Sdanset ::globargs [list]
1066f5d3df40Sdando_execsql_test e_expr-17.3.1 { SELECT 'abc' GLOB 'def' } 1
1067f5d3df40Sdando_test         e_expr-17.3.2 { set globargs } {def abc}
1068f5d3df40Sdanset ::globargs [list]
1069f5d3df40Sdando_execsql_test e_expr-17.3.3 { SELECT 'X' NOT GLOB 'Y' } 0
1070f5d3df40Sdando_test         e_expr-17.3.4 { set globargs } {Y X}
1071f5d3df40Sdansqlite3 db test.db
1072f5d3df40Sdan
1073f5d3df40Sdan# EVIDENCE-OF: R-41650-20872 No regexp() user function is defined by
1074f5d3df40Sdan# default and so use of the REGEXP operator will normally result in an
1075f5d3df40Sdan# error message.
1076f5d3df40Sdan#
10776bd2c735Sdan#   There is a regexp function if ICU is enabled though.
10786bd2c735Sdan#
10796bd2c735Sdanifcapable !icu {
1080f5d3df40Sdan  do_catchsql_test e_expr-18.1.1 {
1081f5d3df40Sdan    SELECT regexp('abc', 'def')
1082f5d3df40Sdan  } {1 {no such function: regexp}}
1083f5d3df40Sdan  do_catchsql_test e_expr-18.1.2 {
1084f5d3df40Sdan    SELECT 'abc' REGEXP 'def'
1085f5d3df40Sdan  } {1 {no such function: REGEXP}}
10866bd2c735Sdan}
1087f5d3df40Sdan
1088f5d3df40Sdan# EVIDENCE-OF: R-33693-50180 The REGEXP operator is a special syntax for
1089f5d3df40Sdan# the regexp() user function.
1090f5d3df40Sdan#
1091f37139f6Sdrh# EVIDENCE-OF: R-65524-61849 If an application-defined SQL function
1092f37139f6Sdrh# named "regexp" is added at run-time, then the "X REGEXP Y" operator
1093f37139f6Sdrh# will be implemented as a call to "regexp(Y,X)".
1094f5d3df40Sdan#
1095f5d3df40Sdanproc regexpfunc {args} {
1096f5d3df40Sdan  eval lappend ::regexpargs $args
1097f5d3df40Sdan  return 1
1098f5d3df40Sdan}
1099f5d3df40Sdandb func regexp -argcount 2 regexpfunc
1100f5d3df40Sdanset ::regexpargs [list]
1101f5d3df40Sdando_execsql_test e_expr-18.2.1 { SELECT 'abc' REGEXP 'def' } 1
1102f5d3df40Sdando_test         e_expr-18.2.2 { set regexpargs } {def abc}
1103f5d3df40Sdanset ::regexpargs [list]
1104f5d3df40Sdando_execsql_test e_expr-18.2.3 { SELECT 'X' NOT REGEXP 'Y' } 0
1105f5d3df40Sdando_test         e_expr-18.2.4 { set regexpargs } {Y X}
1106f5d3df40Sdansqlite3 db test.db
1107f5d3df40Sdan
1108f5d3df40Sdan# EVIDENCE-OF: R-42037-37826 The default match() function implementation
1109f5d3df40Sdan# raises an exception and is not really useful for anything.
1110f5d3df40Sdan#
1111f5d3df40Sdando_catchsql_test e_expr-19.1.1 {
1112f5d3df40Sdan  SELECT 'abc' MATCH 'def'
1113f5d3df40Sdan} {1 {unable to use function MATCH in the requested context}}
1114f5d3df40Sdando_catchsql_test e_expr-19.1.2 {
1115f5d3df40Sdan  SELECT match('abc', 'def')
1116f5d3df40Sdan} {1 {unable to use function MATCH in the requested context}}
1117f5d3df40Sdan
1118f5d3df40Sdan# EVIDENCE-OF: R-37916-47407 The MATCH operator is a special syntax for
1119f5d3df40Sdan# the match() application-defined function.
1120f5d3df40Sdan#
1121f5d3df40Sdan# EVIDENCE-OF: R-06021-09373 But extensions can override the match()
1122f5d3df40Sdan# function with more helpful logic.
1123f5d3df40Sdan#
1124f5d3df40Sdanproc matchfunc {args} {
1125f5d3df40Sdan  eval lappend ::matchargs $args
1126f5d3df40Sdan  return 1
1127f5d3df40Sdan}
1128f5d3df40Sdandb func match -argcount 2 matchfunc
1129f5d3df40Sdanset ::matchargs [list]
1130f5d3df40Sdando_execsql_test e_expr-19.2.1 { SELECT 'abc' MATCH 'def' } 1
1131f5d3df40Sdando_test         e_expr-19.2.2 { set matchargs } {def abc}
1132f5d3df40Sdanset ::matchargs [list]
1133f5d3df40Sdando_execsql_test e_expr-19.2.3 { SELECT 'X' NOT MATCH 'Y' } 0
1134f5d3df40Sdando_test         e_expr-19.2.4 { set matchargs } {Y X}
1135f5d3df40Sdansqlite3 db test.db
1136f5d3df40Sdan
1137eb385b40Sdan#-------------------------------------------------------------------------
1138eb385b40Sdan# Test cases for the testable statements related to the CASE expression.
1139eb385b40Sdan#
1140bbf6d432Sdrh# EVIDENCE-OF: R-57495-24088 There are two fundamental forms of the CASE
1141eb385b40Sdan# expression: those with a base expression and those without.
1142eb385b40Sdan#
1143eb385b40Sdando_execsql_test e_expr-20.1 {
1144eb385b40Sdan  SELECT CASE WHEN 1 THEN 'true' WHEN 0 THEN 'false' ELSE 'else' END;
1145eb385b40Sdan} {true}
1146eb385b40Sdando_execsql_test e_expr-20.2 {
1147eb385b40Sdan  SELECT CASE 0 WHEN 1 THEN 'true' WHEN 0 THEN 'false' ELSE 'else' END;
1148eb385b40Sdan} {false}
1149eb385b40Sdan
1150eb385b40Sdanproc var {nm} {
1151eb385b40Sdan  lappend ::varlist $nm
1152eb385b40Sdan  return [set "::$nm"]
1153eb385b40Sdan}
1154eb385b40Sdandb func var var
1155eb385b40Sdan
1156eb385b40Sdan# EVIDENCE-OF: R-30638-59954 In a CASE without a base expression, each
1157eb385b40Sdan# WHEN expression is evaluated and the result treated as a boolean,
1158eb385b40Sdan# starting with the leftmost and continuing to the right.
1159eb385b40Sdan#
1160eb385b40Sdanforeach {a b c} {0 0 0} break
1161eb385b40Sdanset varlist [list]
1162eb385b40Sdando_execsql_test e_expr-21.1.1 {
1163eb385b40Sdan  SELECT CASE WHEN var('a') THEN 'A'
1164eb385b40Sdan              WHEN var('b') THEN 'B'
1165eb385b40Sdan              WHEN var('c') THEN 'C' END
1166eb385b40Sdan} {{}}
1167eb385b40Sdando_test e_expr-21.1.2 { set varlist } {a b c}
1168eb385b40Sdanset varlist [list]
1169eb385b40Sdando_execsql_test e_expr-21.1.3 {
1170eb385b40Sdan  SELECT CASE WHEN var('c') THEN 'C'
1171eb385b40Sdan              WHEN var('b') THEN 'B'
1172eb385b40Sdan              WHEN var('a') THEN 'A'
1173eb385b40Sdan              ELSE 'no result'
1174eb385b40Sdan  END
1175eb385b40Sdan} {{no result}}
1176eb385b40Sdando_test e_expr-21.1.4 { set varlist } {c b a}
1177eb385b40Sdan
1178eb385b40Sdan# EVIDENCE-OF: R-39009-25596 The result of the CASE expression is the
1179eb385b40Sdan# evaluation of the THEN expression that corresponds to the first WHEN
1180eb385b40Sdan# expression that evaluates to true.
1181eb385b40Sdan#
1182eb385b40Sdanforeach {a b c} {0 1 0} break
1183eb385b40Sdando_execsql_test e_expr-21.2.1 {
1184eb385b40Sdan  SELECT CASE WHEN var('a') THEN 'A'
1185eb385b40Sdan              WHEN var('b') THEN 'B'
1186eb385b40Sdan              WHEN var('c') THEN 'C'
1187eb385b40Sdan              ELSE 'no result'
1188eb385b40Sdan  END
1189eb385b40Sdan} {B}
1190eb385b40Sdanforeach {a b c} {0 1 1} break
1191eb385b40Sdando_execsql_test e_expr-21.2.2 {
1192eb385b40Sdan  SELECT CASE WHEN var('a') THEN 'A'
1193eb385b40Sdan              WHEN var('b') THEN 'B'
1194eb385b40Sdan              WHEN var('c') THEN 'C'
1195eb385b40Sdan              ELSE 'no result'
1196eb385b40Sdan  END
1197eb385b40Sdan} {B}
1198eb385b40Sdanforeach {a b c} {0 0 1} break
1199eb385b40Sdando_execsql_test e_expr-21.2.3 {
1200eb385b40Sdan  SELECT CASE WHEN var('a') THEN 'A'
1201eb385b40Sdan              WHEN var('b') THEN 'B'
1202eb385b40Sdan              WHEN var('c') THEN 'C'
1203eb385b40Sdan              ELSE 'no result'
1204eb385b40Sdan  END
1205eb385b40Sdan} {C}
1206eb385b40Sdan
1207eb385b40Sdan# EVIDENCE-OF: R-24227-04807 Or, if none of the WHEN expressions
1208eb385b40Sdan# evaluate to true, the result of evaluating the ELSE expression, if
1209eb385b40Sdan# any.
1210eb385b40Sdan#
1211eb385b40Sdanforeach {a b c} {0 0 0} break
1212eb385b40Sdando_execsql_test e_expr-21.3.1 {
1213eb385b40Sdan  SELECT CASE WHEN var('a') THEN 'A'
1214eb385b40Sdan              WHEN var('b') THEN 'B'
1215eb385b40Sdan              WHEN var('c') THEN 'C'
1216eb385b40Sdan              ELSE 'no result'
1217eb385b40Sdan  END
1218eb385b40Sdan} {{no result}}
1219eb385b40Sdan
1220eb385b40Sdan# EVIDENCE-OF: R-14168-07579 If there is no ELSE expression and none of
1221eb385b40Sdan# the WHEN expressions are true, then the overall result is NULL.
1222eb385b40Sdan#
1223eb385b40Sdandb nullvalue null
1224eb385b40Sdando_execsql_test e_expr-21.3.2 {
1225eb385b40Sdan  SELECT CASE WHEN var('a') THEN 'A'
1226eb385b40Sdan              WHEN var('b') THEN 'B'
1227eb385b40Sdan              WHEN var('c') THEN 'C'
1228eb385b40Sdan  END
1229eb385b40Sdan} {null}
1230eb385b40Sdandb nullvalue {}
1231eb385b40Sdan
1232eb385b40Sdan# EVIDENCE-OF: R-13943-13592 A NULL result is considered untrue when
1233eb385b40Sdan# evaluating WHEN terms.
1234eb385b40Sdan#
1235eb385b40Sdando_execsql_test e_expr-21.4.1 {
12363c0e606bSdrh  SELECT CASE WHEN NULL THEN 'A' WHEN 1 THEN 'B' END, iif(NULL,8,99);
12373c0e606bSdrh} {B 99}
1238eb385b40Sdando_execsql_test e_expr-21.4.2 {
12393c0e606bSdrh  SELECT CASE WHEN 0 THEN 'A' WHEN NULL THEN 'B' ELSE 'C' END, iif(0,8,99);
12403c0e606bSdrh} {C 99}
1241eb385b40Sdan
1242eb385b40Sdan# EVIDENCE-OF: R-38620-19499 In a CASE with a base expression, the base
1243eb385b40Sdan# expression is evaluated just once and the result is compared against
1244eb385b40Sdan# the evaluation of each WHEN expression from left to right.
1245eb385b40Sdan#
1246eb385b40Sdan# Note: This test case tests the "evaluated just once" part of the above
1247eb385b40Sdan# statement. Tests associated with the next two statements test that the
1248eb385b40Sdan# comparisons take place.
1249eb385b40Sdan#
1250eb385b40Sdanforeach {a b c} [list [expr 3] [expr 4] [expr 5]] break
1251eb385b40Sdanset ::varlist [list]
1252eb385b40Sdando_execsql_test e_expr-22.1.1 {
1253eb385b40Sdan  SELECT CASE var('a') WHEN 1 THEN 'A' WHEN 2 THEN 'B' WHEN 3 THEN 'C' END
1254eb385b40Sdan} {C}
1255eb385b40Sdando_test e_expr-22.1.2 { set ::varlist } {a}
1256eb385b40Sdan
1257eb385b40Sdan# EVIDENCE-OF: R-07667-49537 The result of the CASE expression is the
1258eb385b40Sdan# evaluation of the THEN expression that corresponds to the first WHEN
1259eb385b40Sdan# expression for which the comparison is true.
1260eb385b40Sdan#
1261eb385b40Sdando_execsql_test e_expr-22.2.1 {
1262eb385b40Sdan  SELECT CASE 23 WHEN 1 THEN 'A' WHEN 23 THEN 'B' WHEN 23 THEN 'C' END
1263eb385b40Sdan} {B}
1264eb385b40Sdando_execsql_test e_expr-22.2.2 {
1265eb385b40Sdan  SELECT CASE 1 WHEN 1 THEN 'A' WHEN 23 THEN 'B' WHEN 23 THEN 'C' END
1266eb385b40Sdan} {A}
1267eb385b40Sdan
1268eb385b40Sdan# EVIDENCE-OF: R-47543-32145 Or, if none of the WHEN expressions
1269eb385b40Sdan# evaluate to a value equal to the base expression, the result of
1270eb385b40Sdan# evaluating the ELSE expression, if any.
1271eb385b40Sdan#
1272eb385b40Sdando_execsql_test e_expr-22.3.1 {
1273eb385b40Sdan  SELECT CASE 24 WHEN 1 THEN 'A' WHEN 23 THEN 'B' WHEN 23 THEN 'C' ELSE 'D' END
1274eb385b40Sdan} {D}
1275eb385b40Sdan
1276eb385b40Sdan# EVIDENCE-OF: R-54721-48557 If there is no ELSE expression and none of
1277eb385b40Sdan# the WHEN expressions produce a result equal to the base expression,
1278eb385b40Sdan# the overall result is NULL.
1279eb385b40Sdan#
1280eb385b40Sdando_execsql_test e_expr-22.4.1 {
1281eb385b40Sdan  SELECT CASE 24 WHEN 1 THEN 'A' WHEN 23 THEN 'B' WHEN 23 THEN 'C' END
1282eb385b40Sdan} {{}}
1283eb385b40Sdandb nullvalue null
1284eb385b40Sdando_execsql_test e_expr-22.4.2 {
1285eb385b40Sdan  SELECT CASE 24 WHEN 1 THEN 'A' WHEN 23 THEN 'B' WHEN 23 THEN 'C' END
1286eb385b40Sdan} {null}
1287eb385b40Sdandb nullvalue {}
1288eb385b40Sdan
1289eb385b40Sdan# EVIDENCE-OF: R-11479-62774 When comparing a base expression against a
1290eb385b40Sdan# WHEN expression, the same collating sequence, affinity, and
1291eb385b40Sdan# NULL-handling rules apply as if the base expression and WHEN
1292eb385b40Sdan# expression are respectively the left- and right-hand operands of an =
1293eb385b40Sdan# operator.
1294eb385b40Sdan#
1295eb385b40Sdanproc rev {str} {
1296eb385b40Sdan  set ret ""
1297eb385b40Sdan  set chars [split $str]
1298eb385b40Sdan  for {set i [expr [llength $chars]-1]} {$i>=0} {incr i -1} {
1299eb385b40Sdan    append ret [lindex $chars $i]
1300eb385b40Sdan  }
1301eb385b40Sdan  set ret
1302eb385b40Sdan}
1303eb385b40Sdanproc reverse {lhs rhs} {
1304c0c3c262Sdan  string compare [rev $lhs] [rev $rhs]
1305eb385b40Sdan}
1306eb385b40Sdandb collate reverse reverse
1307eb385b40Sdando_execsql_test e_expr-23.1.1 {
1308eb385b40Sdan  CREATE TABLE t1(
1309eb385b40Sdan    a TEXT     COLLATE NOCASE,
1310eb385b40Sdan    b          COLLATE REVERSE,
1311eb385b40Sdan    c INTEGER,
1312eb385b40Sdan    d BLOB
1313eb385b40Sdan  );
1314eb385b40Sdan  INSERT INTO t1 VALUES('abc', 'cba', 55, 34.5);
1315eb385b40Sdan} {}
1316eb385b40Sdando_execsql_test e_expr-23.1.2 {
1317eb385b40Sdan  SELECT CASE a WHEN 'xyz' THEN 'A' WHEN 'AbC' THEN 'B' END FROM t1
1318eb385b40Sdan} {B}
1319eb385b40Sdando_execsql_test e_expr-23.1.3 {
1320eb385b40Sdan  SELECT CASE 'AbC' WHEN 'abc' THEN 'A' WHEN a THEN 'B' END FROM t1
1321eb385b40Sdan} {B}
1322eb385b40Sdando_execsql_test e_expr-23.1.4 {
1323eb385b40Sdan  SELECT CASE a WHEN b THEN 'A' ELSE 'B' END FROM t1
1324eb385b40Sdan} {B}
1325eb385b40Sdando_execsql_test e_expr-23.1.5 {
1326eb385b40Sdan  SELECT CASE b WHEN a THEN 'A' ELSE 'B' END FROM t1
1327c0c3c262Sdan} {B}
1328eb385b40Sdando_execsql_test e_expr-23.1.6 {
1329eb385b40Sdan  SELECT CASE 55 WHEN '55' THEN 'A' ELSE 'B' END
1330eb385b40Sdan} {B}
1331eb385b40Sdando_execsql_test e_expr-23.1.7 {
1332eb385b40Sdan  SELECT CASE c WHEN '55' THEN 'A' ELSE 'B' END FROM t1
1333eb385b40Sdan} {A}
1334eb385b40Sdando_execsql_test e_expr-23.1.8 {
1335eb385b40Sdan  SELECT CASE '34.5' WHEN d THEN 'A' ELSE 'B' END FROM t1
1336eb385b40Sdan} {B}
1337eb385b40Sdando_execsql_test e_expr-23.1.9 {
1338eb385b40Sdan  SELECT CASE NULL WHEN NULL THEN 'A' ELSE 'B' END
1339eb385b40Sdan} {B}
1340eb385b40Sdan
1341eb385b40Sdan# EVIDENCE-OF: R-37304-39405 If the base expression is NULL then the
1342eb385b40Sdan# result of the CASE is always the result of evaluating the ELSE
1343eb385b40Sdan# expression if it exists, or NULL if it does not.
1344eb385b40Sdan#
1345eb385b40Sdando_execsql_test e_expr-24.1.1 {
1346eb385b40Sdan  SELECT CASE NULL WHEN 'abc' THEN 'A' WHEN 'def' THEN 'B' END;
1347eb385b40Sdan} {{}}
1348eb385b40Sdando_execsql_test e_expr-24.1.2 {
1349eb385b40Sdan  SELECT CASE NULL WHEN 'abc' THEN 'A' WHEN 'def' THEN 'B' ELSE 'C' END;
1350eb385b40Sdan} {C}
1351eb385b40Sdan
1352eb385b40Sdan# EVIDENCE-OF: R-56280-17369 Both forms of the CASE expression use lazy,
1353eb385b40Sdan# or short-circuit, evaluation.
1354eb385b40Sdan#
1355eb385b40Sdanset varlist [list]
1356eb385b40Sdanforeach {a b c} {0 1 0} break
1357eb385b40Sdando_execsql_test e_expr-25.1.1 {
1358eb385b40Sdan  SELECT CASE WHEN var('a') THEN 'A'
1359eb385b40Sdan              WHEN var('b') THEN 'B'
1360eb385b40Sdan              WHEN var('c') THEN 'C'
1361eb385b40Sdan  END
1362eb385b40Sdan} {B}
1363eb385b40Sdando_test e_expr-25.1.2 { set ::varlist } {a b}
1364eb385b40Sdanset varlist [list]
1365eb385b40Sdando_execsql_test e_expr-25.1.3 {
1366eb385b40Sdan  SELECT CASE '0' WHEN var('a') THEN 'A'
1367eb385b40Sdan                  WHEN var('b') THEN 'B'
1368eb385b40Sdan                  WHEN var('c') THEN 'C'
1369eb385b40Sdan  END
1370eb385b40Sdan} {A}
1371eb385b40Sdando_test e_expr-25.1.4 { set ::varlist } {a}
1372eb385b40Sdan
1373eb385b40Sdan# EVIDENCE-OF: R-34773-62253 The only difference between the following
1374eb385b40Sdan# two CASE expressions is that the x expression is evaluated exactly
1375eb385b40Sdan# once in the first example but might be evaluated multiple times in the
1376eb385b40Sdan# second: CASE x WHEN w1 THEN r1 WHEN w2 THEN r2 ELSE r3 END CASE WHEN
1377eb385b40Sdan# x=w1 THEN r1 WHEN x=w2 THEN r2 ELSE r3 END
1378eb385b40Sdan#
1379eb385b40Sdanproc ceval {x} {
1380eb385b40Sdan  incr ::evalcount
1381eb385b40Sdan  return $x
1382eb385b40Sdan}
1383eb385b40Sdandb func ceval ceval
1384eb385b40Sdanset ::evalcount 0
1385eb385b40Sdan
1386eb385b40Sdando_execsql_test e_expr-26.1.1 {
1387eb385b40Sdan  CREATE TABLE t2(x, w1, r1, w2, r2, r3);
1388eb385b40Sdan  INSERT INTO t2 VALUES(1, 1, 'R1', 2, 'R2', 'R3');
1389eb385b40Sdan  INSERT INTO t2 VALUES(2, 1, 'R1', 2, 'R2', 'R3');
1390eb385b40Sdan  INSERT INTO t2 VALUES(3, 1, 'R1', 2, 'R2', 'R3');
1391eb385b40Sdan} {}
1392eb385b40Sdando_execsql_test e_expr-26.1.2 {
1393eb385b40Sdan  SELECT CASE x WHEN w1 THEN r1 WHEN w2 THEN r2 ELSE r3 END FROM t2
1394eb385b40Sdan} {R1 R2 R3}
1395eb385b40Sdando_execsql_test e_expr-26.1.3 {
1396eb385b40Sdan  SELECT CASE WHEN x=w1 THEN r1 WHEN x=w2 THEN r2 ELSE r3 END FROM t2
1397eb385b40Sdan} {R1 R2 R3}
1398eb385b40Sdan
1399eb385b40Sdando_execsql_test e_expr-26.1.4 {
1400eb385b40Sdan  SELECT CASE ceval(x) WHEN w1 THEN r1 WHEN w2 THEN r2 ELSE r3 END FROM t2
1401eb385b40Sdan} {R1 R2 R3}
1402eb385b40Sdando_test e_expr-26.1.5 { set ::evalcount } {3}
1403eb385b40Sdanset ::evalcount 0
1404eb385b40Sdando_execsql_test e_expr-26.1.6 {
1405eb385b40Sdan  SELECT CASE
1406eb385b40Sdan    WHEN ceval(x)=w1 THEN r1
1407eb385b40Sdan    WHEN ceval(x)=w2 THEN r2
1408eb385b40Sdan    ELSE r3 END
1409eb385b40Sdan  FROM t2
1410eb385b40Sdan} {R1 R2 R3}
1411eb385b40Sdando_test e_expr-26.1.6 { set ::evalcount } {5}
1412994e9403Sdan
141351f3a505Sdan
141451f3a505Sdan#-------------------------------------------------------------------------
141551f3a505Sdan# Test statements related to CAST expressions.
141651f3a505Sdan#
14179338642cSdrh# EVIDENCE-OF: R-20854-17109 A CAST conversion is similar to the
14189338642cSdrh# conversion that takes place when a column affinity is applied to a
14199338642cSdrh# value except that with the CAST operator the conversion always takes
14209338642cSdrh# place even if the conversion lossy and irreversible, whereas column
14219338642cSdrh# affinity only changes the data type of a value if the change is
14229338642cSdrh# lossless and reversible.
142351f3a505Sdan#
142451f3a505Sdando_execsql_test e_expr-27.1.1 {
142551f3a505Sdan  CREATE TABLE t3(a TEXT, b REAL, c INTEGER);
142651f3a505Sdan  INSERT INTO t3 VALUES(X'555655', '1.23abc', 4.5);
142751f3a505Sdan  SELECT typeof(a), a, typeof(b), b, typeof(c), c FROM t3;
142851f3a505Sdan} {blob UVU text 1.23abc real 4.5}
142951f3a505Sdando_execsql_test e_expr-27.1.2 {
143051f3a505Sdan  SELECT
143151f3a505Sdan    typeof(CAST(X'555655' as TEXT)), CAST(X'555655' as TEXT),
143251f3a505Sdan    typeof(CAST('1.23abc' as REAL)), CAST('1.23abc' as REAL),
143351f3a505Sdan    typeof(CAST(4.5 as INTEGER)), CAST(4.5 as INTEGER)
143451f3a505Sdan} {text UVU real 1.23 integer 4}
143551f3a505Sdan
1436b3366b99Sdrh# EVIDENCE-OF: R-32434-09092 If the value of expr is NULL, then the
1437b3366b99Sdrh# result of the CAST expression is also NULL.
143851f3a505Sdan#
143951f3a505Sdando_expr_test e_expr-27.2.1 { CAST(NULL AS integer) } null {}
144051f3a505Sdando_expr_test e_expr-27.2.2 { CAST(NULL AS text) }    null {}
144151f3a505Sdando_expr_test e_expr-27.2.3 { CAST(NULL AS blob) }    null {}
144251f3a505Sdando_expr_test e_expr-27.2.4 { CAST(NULL AS number) }  null {}
144351f3a505Sdan
1444e74cc5c9Sdrh# EVIDENCE-OF: R-29283-15561 Otherwise, the storage class of the result
1445e74cc5c9Sdrh# is determined by applying the rules for determining column affinity to
1446e74cc5c9Sdrh# the type-name.
1447e74cc5c9Sdrh#
1448e74cc5c9Sdrh# The R-29283-15561 requirement above is demonstrated by all of the
1449e74cc5c9Sdrh# subsequent e_expr-26 tests.
1450e74cc5c9Sdrh#
1451b3366b99Sdrh# EVIDENCE-OF: R-43522-35548 Casting a value to a type-name with no
1452b3366b99Sdrh# affinity causes the value to be converted into a BLOB.
145351f3a505Sdan#
145451f3a505Sdando_expr_test e_expr-27.3.1 { CAST('abc' AS blob)       } blob abc
145551f3a505Sdando_expr_test e_expr-27.3.2 { CAST('def' AS shobblob_x) } blob def
145651f3a505Sdando_expr_test e_expr-27.3.3 { CAST('ghi' AS abbLOb10)   } blob ghi
145751f3a505Sdan
145851f3a505Sdan# EVIDENCE-OF: R-22956-37754 Casting to a BLOB consists of first casting
145951f3a505Sdan# the value to TEXT in the encoding of the database connection, then
146051f3a505Sdan# interpreting the resulting byte sequence as a BLOB instead of as TEXT.
146151f3a505Sdan#
146251f3a505Sdando_qexpr_test e_expr-27.4.1 { CAST('ghi' AS blob) } X'676869'
146351f3a505Sdando_qexpr_test e_expr-27.4.2 { CAST(456 AS blob) }   X'343536'
146451f3a505Sdando_qexpr_test e_expr-27.4.3 { CAST(1.78 AS blob) }  X'312E3738'
146551f3a505Sdanrename db db2
146651f3a505Sdansqlite3 db :memory:
14676faa5fdfSshanehifcapable {utf16} {
146851f3a505Sdandb eval { PRAGMA encoding = 'utf-16le' }
146951f3a505Sdando_qexpr_test e_expr-27.4.4 { CAST('ghi' AS blob) } X'670068006900'
147051f3a505Sdando_qexpr_test e_expr-27.4.5 { CAST(456 AS blob) }   X'340035003600'
147151f3a505Sdando_qexpr_test e_expr-27.4.6 { CAST(1.78 AS blob) }  X'31002E0037003800'
14726faa5fdfSshaneh}
147351f3a505Sdandb close
147451f3a505Sdansqlite3 db :memory:
147551f3a505Sdandb eval { PRAGMA encoding = 'utf-16be' }
14766faa5fdfSshanehifcapable {utf16} {
147751f3a505Sdando_qexpr_test e_expr-27.4.7 { CAST('ghi' AS blob) } X'006700680069'
147851f3a505Sdando_qexpr_test e_expr-27.4.8 { CAST(456 AS blob) }   X'003400350036'
147951f3a505Sdando_qexpr_test e_expr-27.4.9 { CAST(1.78 AS blob) }  X'0031002E00370038'
14806faa5fdfSshaneh}
148151f3a505Sdandb close
148251f3a505Sdanrename db2 db
148351f3a505Sdan
148451f3a505Sdan# EVIDENCE-OF: R-04207-37981 To cast a BLOB value to TEXT, the sequence
148551f3a505Sdan# of bytes that make up the BLOB is interpreted as text encoded using
148651f3a505Sdan# the database encoding.
148751f3a505Sdan#
148851f3a505Sdando_expr_test e_expr-28.1.1 { CAST (X'676869' AS text) } text ghi
148951f3a505Sdando_expr_test e_expr-28.1.2 { CAST (X'670068006900' AS text) } text g
149051f3a505Sdanrename db db2
149151f3a505Sdansqlite3 db :memory:
149251f3a505Sdandb eval { PRAGMA encoding = 'utf-16le' }
14936faa5fdfSshanehifcapable {utf16} {
149451f3a505Sdando_expr_test e_expr-28.1.3 { CAST (X'676869' AS text) == 'ghi' } integer 0
149551f3a505Sdando_expr_test e_expr-28.1.4 { CAST (X'670068006900' AS text) } text ghi
14966faa5fdfSshaneh}
149751f3a505Sdandb close
149851f3a505Sdanrename db2 db
149951f3a505Sdan
150051f3a505Sdan# EVIDENCE-OF: R-22235-47006 Casting an INTEGER or REAL value into TEXT
150151f3a505Sdan# renders the value as if via sqlite3_snprintf() except that the
150251f3a505Sdan# resulting TEXT uses the encoding of the database connection.
150351f3a505Sdan#
150451f3a505Sdando_expr_test e_expr-28.2.1 { CAST (1 AS text)   }     text 1
150551f3a505Sdando_expr_test e_expr-28.2.2 { CAST (45 AS text)  }     text 45
150651f3a505Sdando_expr_test e_expr-28.2.3 { CAST (-45 AS text) }     text -45
150751f3a505Sdando_expr_test e_expr-28.2.4 { CAST (8.8 AS text)    }  text 8.8
150851f3a505Sdando_expr_test e_expr-28.2.5 { CAST (2.3e+5 AS text) }  text 230000.0
150951f3a505Sdando_expr_test e_expr-28.2.6 { CAST (-2.3e-5 AS text) } text -2.3e-05
151051f3a505Sdando_expr_test e_expr-28.2.7 { CAST (0.0 AS text) }     text 0.0
151151f3a505Sdando_expr_test e_expr-28.2.7 { CAST (0 AS text) }       text 0
151251f3a505Sdan
151351f3a505Sdan# EVIDENCE-OF: R-26346-36443 When casting a BLOB value to a REAL, the
151451f3a505Sdan# value is first converted to TEXT.
151551f3a505Sdan#
151651f3a505Sdando_expr_test e_expr-29.1.1 { CAST (X'312E3233' AS REAL) } real 1.23
151751f3a505Sdando_expr_test e_expr-29.1.2 { CAST (X'3233302E30' AS REAL) } real 230.0
151851f3a505Sdando_expr_test e_expr-29.1.3 { CAST (X'2D392E3837' AS REAL) } real -9.87
151951f3a505Sdando_expr_test e_expr-29.1.4 { CAST (X'302E30303031' AS REAL) } real 0.0001
152051f3a505Sdanrename db db2
152151f3a505Sdansqlite3 db :memory:
15226faa5fdfSshanehifcapable {utf16} {
152351f3a505Sdandb eval { PRAGMA encoding = 'utf-16le' }
152448d9e01eSdando_expr_test e_expr-29.1.5 {
152551f3a505Sdan    CAST (X'31002E0032003300' AS REAL) } real 1.23
152648d9e01eSdando_expr_test e_expr-29.1.6 {
152751f3a505Sdan    CAST (X'3200330030002E003000' AS REAL) } real 230.0
152848d9e01eSdando_expr_test e_expr-29.1.7 {
152951f3a505Sdan    CAST (X'2D0039002E0038003700' AS REAL) } real -9.87
153048d9e01eSdando_expr_test e_expr-29.1.8 {
153151f3a505Sdan    CAST (X'30002E003000300030003100' AS REAL) } real 0.0001
15326faa5fdfSshaneh}
153351f3a505Sdandb close
153451f3a505Sdanrename db2 db
153551f3a505Sdan
153648d9e01eSdan# EVIDENCE-OF: R-54898-34554 When casting a TEXT value to REAL, the
153748d9e01eSdan# longest possible prefix of the value that can be interpreted as a real
153848d9e01eSdan# number is extracted from the TEXT value and the remainder ignored.
153948d9e01eSdan#
154048d9e01eSdando_expr_test e_expr-29.2.1 { CAST('1.23abcd' AS REAL) } real 1.23
154148d9e01eSdando_expr_test e_expr-29.2.2 { CAST('1.45.23abcd' AS REAL) } real 1.45
154248d9e01eSdando_expr_test e_expr-29.2.3 { CAST('-2.12e-01ABC' AS REAL) } real -0.212
154348d9e01eSdando_expr_test e_expr-29.2.4 { CAST('1 2 3 4' AS REAL) } real 1.0
154451f3a505Sdan
154548d9e01eSdan# EVIDENCE-OF: R-11321-47427 Any leading spaces in the TEXT value are
154648d9e01eSdan# ignored when converging from TEXT to REAL.
154748d9e01eSdan#
154848d9e01eSdando_expr_test e_expr-29.3.1 { CAST(' 1.23abcd' AS REAL) } real 1.23
154948d9e01eSdando_expr_test e_expr-29.3.2 { CAST('    1.45.23abcd' AS REAL) } real 1.45
155048d9e01eSdando_expr_test e_expr-29.3.3 { CAST('   -2.12e-01ABC' AS REAL) } real -0.212
155148d9e01eSdando_expr_test e_expr-29.3.4 { CAST(' 1 2 3 4' AS REAL) } real 1.0
155248d9e01eSdan
155348d9e01eSdan# EVIDENCE-OF: R-22662-28218 If there is no prefix that can be
155448d9e01eSdan# interpreted as a real number, the result of the conversion is 0.0.
155548d9e01eSdan#
155648d9e01eSdando_expr_test e_expr-29.4.1 { CAST('' AS REAL) } real 0.0
155748d9e01eSdando_expr_test e_expr-29.4.2 { CAST('not a number' AS REAL) } real 0.0
155848d9e01eSdando_expr_test e_expr-29.4.3 { CAST('XXI' AS REAL) } real 0.0
155948d9e01eSdan
156048d9e01eSdan# EVIDENCE-OF: R-21829-14563 When casting a BLOB value to INTEGER, the
156148d9e01eSdan# value is first converted to TEXT.
156248d9e01eSdan#
156348d9e01eSdando_expr_test e_expr-30.1.1 { CAST(X'313233' AS INTEGER) } integer 123
156448d9e01eSdando_expr_test e_expr-30.1.2 { CAST(X'2D363738' AS INTEGER) } integer -678
156548d9e01eSdando_expr_test e_expr-30.1.3 {
156648d9e01eSdan  CAST(X'31303030303030' AS INTEGER)
156748d9e01eSdan} integer 1000000
156848d9e01eSdando_expr_test e_expr-30.1.4 {
156948d9e01eSdan  CAST(X'2D31313235383939393036383432363234' AS INTEGER)
157048d9e01eSdan} integer -1125899906842624
157148d9e01eSdan
157248d9e01eSdanrename db db2
157348d9e01eSdansqlite3 db :memory:
15746faa5fdfSshanehifcapable {utf16} {
157548d9e01eSdanexecsql { PRAGMA encoding = 'utf-16be' }
157648d9e01eSdando_expr_test e_expr-30.1.5 { CAST(X'003100320033' AS INTEGER) } integer 123
157748d9e01eSdando_expr_test e_expr-30.1.6 { CAST(X'002D003600370038' AS INTEGER) } integer -678
157848d9e01eSdando_expr_test e_expr-30.1.7 {
157948d9e01eSdan  CAST(X'0031003000300030003000300030' AS INTEGER)
158048d9e01eSdan} integer 1000000
158148d9e01eSdando_expr_test e_expr-30.1.8 {
158248d9e01eSdan  CAST(X'002D0031003100320035003800390039003900300036003800340032003600320034' AS INTEGER)
158348d9e01eSdan} integer -1125899906842624
15846faa5fdfSshaneh}
158548d9e01eSdandb close
158648d9e01eSdanrename db2 db
158748d9e01eSdan
158848d9e01eSdan# EVIDENCE-OF: R-47612-45842 When casting a TEXT value to INTEGER, the
158948d9e01eSdan# longest possible prefix of the value that can be interpreted as an
159048d9e01eSdan# integer number is extracted from the TEXT value and the remainder
159148d9e01eSdan# ignored.
159248d9e01eSdan#
159348d9e01eSdando_expr_test e_expr-30.2.1 { CAST('123abcd' AS INT) } integer 123
159448d9e01eSdando_expr_test e_expr-30.2.2 { CAST('14523abcd' AS INT) } integer 14523
159548d9e01eSdando_expr_test e_expr-30.2.3 { CAST('-2.12e-01ABC' AS INT) } integer -2
159648d9e01eSdando_expr_test e_expr-30.2.4 { CAST('1 2 3 4' AS INT) } integer 1
159748d9e01eSdan
159848d9e01eSdan# EVIDENCE-OF: R-34400-33772 Any leading spaces in the TEXT value when
159948d9e01eSdan# converting from TEXT to INTEGER are ignored.
160048d9e01eSdan#
160148d9e01eSdando_expr_test e_expr-30.3.1 { CAST('   123abcd' AS INT) } integer 123
160248d9e01eSdando_expr_test e_expr-30.3.2 { CAST('  14523abcd' AS INT) } integer 14523
160348d9e01eSdando_expr_test e_expr-30.3.3 { CAST(' -2.12e-01ABC' AS INT) } integer -2
160448d9e01eSdando_expr_test e_expr-30.3.4 { CAST('     1 2 3 4' AS INT) } integer 1
160548d9e01eSdan
160648d9e01eSdan# EVIDENCE-OF: R-43164-44276 If there is no prefix that can be
160748d9e01eSdan# interpreted as an integer number, the result of the conversion is 0.
160848d9e01eSdan#
160948d9e01eSdando_expr_test e_expr-30.4.1 { CAST('' AS INTEGER) } integer 0
161048d9e01eSdando_expr_test e_expr-30.4.2 { CAST('not a number' AS INTEGER) } integer 0
161148d9e01eSdando_expr_test e_expr-30.4.3 { CAST('XXI' AS INTEGER) } integer 0
161248d9e01eSdan
16139f959b07Sdrh# EVIDENCE-OF: R-08980-53124 The CAST operator understands decimal
16149f959b07Sdrh# integers only &mdash; conversion of hexadecimal integers stops at
16159f959b07Sdrh# the "x" in the "0x" prefix of the hexadecimal integer string and thus
16169f959b07Sdrh# result of the CAST is always zero.
16179f959b07Sdrhdo_expr_test e_expr-30.5.1 { CAST('0x1234' AS INTEGER) } integer 0
16189f959b07Sdrhdo_expr_test e_expr-30.5.2 { CAST('0X1234' AS INTEGER) } integer 0
16199f959b07Sdrh
16209338642cSdrh# EVIDENCE-OF: R-02752-50091 A cast of a REAL value into an INTEGER
16219338642cSdrh# results in the integer between the REAL value and zero that is closest
16229338642cSdrh# to the REAL value.
162348d9e01eSdan#
162448d9e01eSdando_expr_test e_expr-31.1.1 { CAST(3.14159 AS INTEGER) } integer 3
162548d9e01eSdando_expr_test e_expr-31.1.2 { CAST(1.99999 AS INTEGER) } integer 1
162648d9e01eSdando_expr_test e_expr-31.1.3 { CAST(-1.99999 AS INTEGER) } integer -1
162748d9e01eSdando_expr_test e_expr-31.1.4 { CAST(-0.99999 AS INTEGER) } integer 0
162848d9e01eSdan
16291bcbc6a6Sdrh# EVIDENCE-OF: R-51517-40824 If a REAL is greater than the greatest
16301bcbc6a6Sdrh# possible signed integer (+9223372036854775807) then the result is the
16311bcbc6a6Sdrh# greatest possible signed integer and if the REAL is less than the
16321bcbc6a6Sdrh# least possible signed integer (-9223372036854775808) then the result
16331bcbc6a6Sdrh# is the least possible signed integer.
163448d9e01eSdan#
1635de1a8b8cSdrhdo_expr_test e_expr-31.2.1 { CAST(2e+50 AS INT) } integer 9223372036854775807
163648d9e01eSdando_expr_test e_expr-31.2.2 { CAST(-2e+50 AS INT) } integer -9223372036854775808
163748d9e01eSdando_expr_test e_expr-31.2.3 {
163848d9e01eSdan  CAST(-9223372036854775809.0 AS INT)
163948d9e01eSdan} integer -9223372036854775808
164048d9e01eSdando_expr_test e_expr-31.2.4 {
164148d9e01eSdan  CAST(9223372036854775809.0 AS INT)
1642de1a8b8cSdrh} integer 9223372036854775807
164348d9e01eSdan
164448d9e01eSdan
16450ce974d1Sdrh# EVIDENCE-OF: R-55084-10555 Casting a TEXT or BLOB value into NUMERIC
16460ce974d1Sdrh# yields either an INTEGER or a REAL result.
16470ce974d1Sdrh#
16480ce974d1Sdrh# EVIDENCE-OF: R-48945-04866 If the input text looks like an integer
16490ce974d1Sdrh# (there is no decimal point nor exponent) and the value is small enough
16500ce974d1Sdrh# to fit in a 64-bit signed integer, then the result will be INTEGER.
16510ce974d1Sdrh#
16520ce974d1Sdrh# EVIDENCE-OF: R-47045-23194 Input text that looks like floating point
16530ce974d1Sdrh# (there is a decimal point and/or an exponent) and the text describes a
16540ce974d1Sdrh# value that can be losslessly converted back and forth between IEEE 754
16550ce974d1Sdrh# 64-bit float and a 51-bit signed integer, then the result is INTEGER.
165648d9e01eSdan#
165748d9e01eSdando_expr_test e_expr-32.1.1 { CAST('45'   AS NUMERIC)  } integer 45
1658c285ded2Sdrhdo_expr_test e_expr-32.1.2 { CAST('45.0' AS NUMERIC)  } integer 45
165948d9e01eSdando_expr_test e_expr-32.1.3 { CAST('45.2' AS NUMERIC)  } real 45.2
166048d9e01eSdando_expr_test e_expr-32.1.4 { CAST('11abc' AS NUMERIC) } integer 11
166148d9e01eSdando_expr_test e_expr-32.1.5 { CAST('11.1abc' AS NUMERIC) } real 11.1
16620ce974d1Sdrhdo_expr_test e_expr-32.1.6 {CAST( '9.223372036e14' AS NUMERIC)} integer  922337203600000
16630ce974d1Sdrhdo_expr_test e_expr-32.1.7 {CAST('-9.223372036e14' AS NUMERIC)} integer -922337203600000
16645710f1adSdrhdo_test e_expr-32.1.8 {
16655710f1adSdrh  set expr {CAST( '9.223372036e15' AS NUMERIC)}
16665710f1adSdrh  db eval "SELECT typeof($expr) AS type, printf('%.5e',$expr) AS value"  break;
16675710f1adSdrh  list $type $value
16685710f1adSdrh} {real 9.22337e+15}
16695710f1adSdrhdo_test e_expr-32.1.9 {
16705710f1adSdrh  set expr {CAST('-9.223372036e15' AS NUMERIC)}
16715710f1adSdrh  db eval "SELECT typeof($expr) AS type, printf('%.5e',$expr) AS value"  break;
16725710f1adSdrh  list $type $value
16735710f1adSdrh} {real -9.22337e+15}
16740ce974d1Sdrh
16750ce974d1Sdrh# EVIDENCE-OF: R-50300-26941 Any text input that describes a value
16760ce974d1Sdrh# outside the range of a 64-bit signed integer yields a REAL result.
16770ce974d1Sdrh#
16780ce974d1Sdrhdo_expr_test e_expr-32.1.20 { CAST('9223372036854775807' AS numeric) } \
16790ce974d1Sdrh   integer 9223372036854775807
16800ce974d1Sdrhdo_expr_test e_expr-32.1.21 { CAST('9223372036854775808' AS numeric) } \
16810ce974d1Sdrh   real 9.22337203685478e+18
16820ce974d1Sdrhdo_expr_test e_expr-32.1.22 { CAST('-9223372036854775808' AS numeric) } \
16830ce974d1Sdrh   integer -9223372036854775808
16840ce974d1Sdrhdo_expr_test e_expr-32.1.23 { CAST('-9223372036854775809' AS numeric) } \
16850ce974d1Sdrh   real -9.22337203685478e+18
168648d9e01eSdan
168748d9e01eSdan# EVIDENCE-OF: R-30347-18702 Casting a REAL or INTEGER value to NUMERIC
168848d9e01eSdan# is a no-op, even if a real value could be losslessly converted to an
168948d9e01eSdan# integer.
169048d9e01eSdan#
169148d9e01eSdando_expr_test e_expr-32.2.1 { CAST(13.0 AS NUMERIC) } real 13.0
169248d9e01eSdando_expr_test e_expr-32.2.2 { CAST(13.5 AS NUMERIC) } real 13.5
169348d9e01eSdan
169448d9e01eSdando_expr_test e_expr-32.2.3 {
169548d9e01eSdan  CAST(-9223372036854775808 AS NUMERIC)
169648d9e01eSdan} integer -9223372036854775808
169748d9e01eSdando_expr_test e_expr-32.2.4 {
169848d9e01eSdan  CAST(9223372036854775807 AS NUMERIC)
169948d9e01eSdan} integer 9223372036854775807
170084d4f1a3Sdrhdo_expr_test e_expr-32.2.5 {
170184d4f1a3Sdrh  CAST('9223372036854775807 ' AS NUMERIC)
170284d4f1a3Sdrh} integer 9223372036854775807
170384d4f1a3Sdrhdo_expr_test e_expr-32.2.6 {
170484d4f1a3Sdrh  CAST('   9223372036854775807   ' AS NUMERIC)
170584d4f1a3Sdrh} integer 9223372036854775807
170684d4f1a3Sdrhdo_expr_test e_expr-32.2.7 {
170784d4f1a3Sdrh  CAST('  ' AS NUMERIC)
170884d4f1a3Sdrh} integer 0
170984d4f1a3Sdrhdo_execsql_test e_expr-32.2.8 {
171084d4f1a3Sdrh  WITH t1(x) AS (VALUES
171184d4f1a3Sdrh     ('9000000000000000001'),
171284d4f1a3Sdrh     ('9000000000000000001x'),
171384d4f1a3Sdrh     ('9000000000000000001 '),
171484d4f1a3Sdrh     (' 9000000000000000001 '),
171584d4f1a3Sdrh     (' 9000000000000000001'),
171684d4f1a3Sdrh     (' 9000000000000000001.'),
171784d4f1a3Sdrh     ('9223372036854775807'),
171884d4f1a3Sdrh     ('9223372036854775807 '),
171984d4f1a3Sdrh     ('   9223372036854775807   '),
172084d4f1a3Sdrh     ('9223372036854775808'),
172184d4f1a3Sdrh     ('   9223372036854775808   '),
172284d4f1a3Sdrh     ('9223372036854775807.0'),
172384d4f1a3Sdrh     ('9223372036854775807e+0'),
172484d4f1a3Sdrh     ('-5.0'),
172584d4f1a3Sdrh     ('-5e+0'))
172684d4f1a3Sdrh  SELECT typeof(CAST(x AS NUMERIC)), CAST(x AS NUMERIC)||'' FROM t1;
172784d4f1a3Sdrh} [list \
172884d4f1a3Sdrh integer 9000000000000000001 \
172984d4f1a3Sdrh integer 9000000000000000001 \
173084d4f1a3Sdrh integer 9000000000000000001 \
173184d4f1a3Sdrh integer 9000000000000000001 \
173284d4f1a3Sdrh integer 9000000000000000001 \
17339a278229Sdrh real 9.0e+18 \
173484d4f1a3Sdrh integer 9223372036854775807 \
173584d4f1a3Sdrh integer 9223372036854775807 \
173684d4f1a3Sdrh integer 9223372036854775807 \
173784d4f1a3Sdrh real 9.22337203685478e+18 \
173884d4f1a3Sdrh real 9.22337203685478e+18 \
17399a278229Sdrh real 9.22337203685478e+18 \
17409a278229Sdrh real 9.22337203685478e+18 \
1741c285ded2Sdrh integer -5 \
1742c285ded2Sdrh integer -5 \
174384d4f1a3Sdrh]
174448d9e01eSdan
174548d9e01eSdan# EVIDENCE-OF: R-64550-29191 Note that the result from casting any
174648d9e01eSdan# non-BLOB value into a BLOB and the result from casting any BLOB value
174748d9e01eSdan# into a non-BLOB value may be different depending on whether the
174848d9e01eSdan# database encoding is UTF-8, UTF-16be, or UTF-16le.
174948d9e01eSdan#
17506faa5fdfSshanehifcapable {utf16} {
175148d9e01eSdansqlite3 db1 :memory: ; db1 eval { PRAGMA encoding = 'utf-8' }
175248d9e01eSdansqlite3 db2 :memory: ; db2 eval { PRAGMA encoding = 'utf-16le' }
175348d9e01eSdansqlite3 db3 :memory: ; db3 eval { PRAGMA encoding = 'utf-16be' }
175448d9e01eSdanforeach {tn castexpr differs} {
175548d9e01eSdan  1 { CAST(123 AS BLOB)    } 1
175648d9e01eSdan  2 { CAST('' AS BLOB)     } 0
175748d9e01eSdan  3 { CAST('abcd' AS BLOB) } 1
175848d9e01eSdan
175948d9e01eSdan  4 { CAST(X'abcd' AS TEXT) } 1
176048d9e01eSdan  5 { CAST(X'' AS TEXT)     } 0
176148d9e01eSdan} {
176248d9e01eSdan  set r1 [db1 eval "SELECT typeof($castexpr), quote($castexpr)"]
176348d9e01eSdan  set r2 [db2 eval "SELECT typeof($castexpr), quote($castexpr)"]
176448d9e01eSdan  set r3 [db3 eval "SELECT typeof($castexpr), quote($castexpr)"]
176548d9e01eSdan
176648d9e01eSdan  if {$differs} {
176748d9e01eSdan    set res [expr {$r1!=$r2 && $r2!=$r3}]
176848d9e01eSdan  } else {
176948d9e01eSdan    set res [expr {$r1==$r2 && $r2==$r3}]
177048d9e01eSdan  }
177148d9e01eSdan
177248d9e01eSdan  do_test e_expr-33.1.$tn {set res} 1
177348d9e01eSdan}
177448d9e01eSdandb1 close
177548d9e01eSdandb2 close
177648d9e01eSdandb3 close
17776faa5fdfSshaneh}
177848d9e01eSdan
17794336cc45Sdan#-------------------------------------------------------------------------
17804336cc45Sdan# Test statements related to the EXISTS and NOT EXISTS operators.
17814336cc45Sdan#
17824336cc45Sdancatch { db close }
1783fda06befSmistachkinforcedelete test.db
17844336cc45Sdansqlite3 db test.db
17854336cc45Sdan
17864336cc45Sdando_execsql_test e_expr-34.1 {
17874336cc45Sdan  CREATE TABLE t1(a, b);
17884336cc45Sdan  INSERT INTO t1 VALUES(1, 2);
17894336cc45Sdan  INSERT INTO t1 VALUES(NULL, 2);
17904336cc45Sdan  INSERT INTO t1 VALUES(1, NULL);
17914336cc45Sdan  INSERT INTO t1 VALUES(NULL, NULL);
17924336cc45Sdan} {}
17934336cc45Sdan
17944336cc45Sdan# EVIDENCE-OF: R-25588-27181 The EXISTS operator always evaluates to one
17954336cc45Sdan# of the integer values 0 and 1.
17964336cc45Sdan#
17974336cc45Sdan# This statement is not tested by itself. Instead, all e_expr-34.* tests
17984336cc45Sdan# following this point explicitly test that specific invocations of EXISTS
17994336cc45Sdan# return either integer 0 or integer 1.
18004336cc45Sdan#
18014336cc45Sdan
18024336cc45Sdan# EVIDENCE-OF: R-58553-63740 If executing the SELECT statement specified
18034336cc45Sdan# as the right-hand operand of the EXISTS operator would return one or
18044336cc45Sdan# more rows, then the EXISTS operator evaluates to 1.
18054336cc45Sdan#
18064336cc45Sdanforeach {tn expr} {
18074336cc45Sdan    1 { EXISTS ( SELECT a FROM t1 ) }
18084336cc45Sdan    2 { EXISTS ( SELECT b FROM t1 ) }
18094336cc45Sdan    3 { EXISTS ( SELECT 24 ) }
18104336cc45Sdan    4 { EXISTS ( SELECT NULL ) }
18114336cc45Sdan    5 { EXISTS ( SELECT a FROM t1 WHERE a IS NULL ) }
18124336cc45Sdan} {
18134336cc45Sdan  do_expr_test e_expr-34.2.$tn $expr integer 1
18144336cc45Sdan}
18154336cc45Sdan
18164336cc45Sdan# EVIDENCE-OF: R-19673-40972 If executing the SELECT would return no
18174336cc45Sdan# rows at all, then the EXISTS operator evaluates to 0.
18184336cc45Sdan#
18194336cc45Sdanforeach {tn expr} {
18204336cc45Sdan    1 { EXISTS ( SELECT a FROM t1 WHERE 0) }
18214336cc45Sdan    2 { EXISTS ( SELECT b FROM t1 WHERE a = 5) }
18224336cc45Sdan    3 { EXISTS ( SELECT 24 WHERE 0) }
18234336cc45Sdan    4 { EXISTS ( SELECT NULL WHERE 1=2) }
18244336cc45Sdan} {
18254336cc45Sdan  do_expr_test e_expr-34.3.$tn $expr integer 0
18264336cc45Sdan}
18274336cc45Sdan
18284336cc45Sdan# EVIDENCE-OF: R-35109-49139 The number of columns in each row returned
18294336cc45Sdan# by the SELECT statement (if any) and the specific values returned have
18304336cc45Sdan# no effect on the results of the EXISTS operator.
18314336cc45Sdan#
18324336cc45Sdanforeach {tn expr res} {
18334336cc45Sdan    1 { EXISTS ( SELECT * FROM t1 ) }                          1
18344336cc45Sdan    2 { EXISTS ( SELECT *, *, * FROM t1 ) }                    1
18354336cc45Sdan    3 { EXISTS ( SELECT 24, 25 ) }                             1
18364336cc45Sdan    4 { EXISTS ( SELECT NULL, NULL, NULL ) }                   1
18374336cc45Sdan    5 { EXISTS ( SELECT a,b,a||b FROM t1 WHERE a IS NULL ) }   1
18384336cc45Sdan
18394336cc45Sdan    6 { EXISTS ( SELECT a, a FROM t1 WHERE 0) }                0
18404336cc45Sdan    7 { EXISTS ( SELECT b, b, a FROM t1 WHERE a = 5) }         0
18414336cc45Sdan    8 { EXISTS ( SELECT 24, 46, 89 WHERE 0) }                  0
18424336cc45Sdan    9 { EXISTS ( SELECT NULL, NULL WHERE 1=2) }                0
18434336cc45Sdan} {
18444336cc45Sdan  do_expr_test e_expr-34.4.$tn $expr integer $res
18454336cc45Sdan}
18464336cc45Sdan
18474336cc45Sdan# EVIDENCE-OF: R-10645-12439 In particular, rows containing NULL values
18484336cc45Sdan# are not handled any differently from rows without NULL values.
18494336cc45Sdan#
18504336cc45Sdanforeach {tn e1 e2} {
18514336cc45Sdan  1 { EXISTS (SELECT 'not null') }    { EXISTS (SELECT NULL) }
18524336cc45Sdan  2 { EXISTS (SELECT NULL FROM t1) }  { EXISTS (SELECT 'bread' FROM t1) }
18534336cc45Sdan} {
18544336cc45Sdan  set res [db one "SELECT $e1"]
18554336cc45Sdan  do_expr_test e_expr-34.5.${tn}a $e1 integer $res
18564336cc45Sdan  do_expr_test e_expr-34.5.${tn}b $e2 integer $res
18574336cc45Sdan}
18584336cc45Sdan
18594336cc45Sdan#-------------------------------------------------------------------------
186074b617b2Sdan# Test statements related to scalar sub-queries.
18614336cc45Sdan#
18624336cc45Sdan
186374b617b2Sdancatch { db close }
1864fda06befSmistachkinforcedelete test.db
186574b617b2Sdansqlite3 db test.db
186674b617b2Sdando_test e_expr-35.0 {
186774b617b2Sdan  execsql {
186874b617b2Sdan    CREATE TABLE t2(a, b);
186974b617b2Sdan    INSERT INTO t2 VALUES('one', 'two');
187074b617b2Sdan    INSERT INTO t2 VALUES('three', NULL);
187174b617b2Sdan    INSERT INTO t2 VALUES(4, 5.0);
187274b617b2Sdan  }
187374b617b2Sdan} {}
187474b617b2Sdan
187550da6635Sdrh# EVIDENCE-OF: R-43573-23448 A SELECT statement enclosed in parentheses
187650da6635Sdrh# is a subquery.
187774b617b2Sdan#
187874b617b2Sdan# EVIDENCE-OF: R-56294-03966 All types of SELECT statement, including
187974b617b2Sdan# aggregate and compound SELECT queries (queries with keywords like
188074b617b2Sdan# UNION or EXCEPT) are allowed as scalar subqueries.
188174b617b2Sdan#
188274b617b2Sdando_expr_test e_expr-35.1.1 { (SELECT 35)   } integer 35
188374b617b2Sdando_expr_test e_expr-35.1.2 { (SELECT NULL) } null {}
188474b617b2Sdan
188574b617b2Sdando_expr_test e_expr-35.1.3 { (SELECT count(*) FROM t2) } integer 3
188674b617b2Sdando_expr_test e_expr-35.1.4 { (SELECT 4 FROM t2) } integer 4
188774b617b2Sdan
188874b617b2Sdando_expr_test e_expr-35.1.5 {
188974b617b2Sdan  (SELECT b FROM t2 UNION SELECT a+1 FROM t2)
189074b617b2Sdan} null {}
189174b617b2Sdando_expr_test e_expr-35.1.6 {
189274b617b2Sdan  (SELECT a FROM t2 UNION SELECT COALESCE(b, 55) FROM t2 ORDER BY 1)
189374b617b2Sdan} integer 4
189474b617b2Sdan
189550da6635Sdrh# EVIDENCE-OF: R-22239-33740 A subquery that returns two or more columns
189650da6635Sdrh# is a row value subquery and can only be used as the operand of a
189750da6635Sdrh# comparison operator.
189874b617b2Sdan#
189906ce4136Sdan# The following block tests that errors are returned in a bunch of cases
190006ce4136Sdan# where a subquery returns more than one column.
190106ce4136Sdan#
19028da209b1Sdanset M {/1 {sub-select returns [23] columns - expected 1}/}
190374b617b2Sdanforeach {tn sql} {
190474b617b2Sdan  1     { SELECT (SELECT * FROM t2 UNION SELECT a+1, b+1 FROM t2) }
190574b617b2Sdan  2     { SELECT (SELECT * FROM t2 UNION SELECT a+1, b+1 FROM t2 ORDER BY 1) }
190674b617b2Sdan  3     { SELECT (SELECT 1, 2) }
190774b617b2Sdan  4     { SELECT (SELECT NULL, NULL, NULL) }
190874b617b2Sdan  5     { SELECT (SELECT * FROM t2) }
190974b617b2Sdan  6     { SELECT (SELECT * FROM (SELECT 1, 2, 3)) }
191074b617b2Sdan} {
19118da209b1Sdan  do_catchsql_test e_expr-35.2.$tn $sql $M
191274b617b2Sdan}
191374b617b2Sdan
191450da6635Sdrh# EVIDENCE-OF: R-18318-14995 The value of a subquery expression is the
191550da6635Sdrh# first row of the result from the enclosed SELECT statement.
191606ce4136Sdan#
191706ce4136Sdando_execsql_test e_expr-36.3.1 {
191806ce4136Sdan  CREATE TABLE t4(x, y);
191906ce4136Sdan  INSERT INTO t4 VALUES(1, 'one');
192006ce4136Sdan  INSERT INTO t4 VALUES(2, 'two');
192106ce4136Sdan  INSERT INTO t4 VALUES(3, 'three');
192206ce4136Sdan} {}
192306ce4136Sdan
192406ce4136Sdanforeach {tn expr restype resval} {
192506ce4136Sdan    2  { ( SELECT x FROM t4 ORDER BY x )      }        integer 1
192606ce4136Sdan    3  { ( SELECT x FROM t4 ORDER BY y )      }        integer 1
192706ce4136Sdan    4  { ( SELECT x FROM t4 ORDER BY x DESC ) }        integer 3
192806ce4136Sdan    5  { ( SELECT x FROM t4 ORDER BY y DESC ) }        integer 2
192906ce4136Sdan    6  { ( SELECT y FROM t4 ORDER BY y DESC ) }        text    two
193006ce4136Sdan
193106ce4136Sdan    7  { ( SELECT sum(x) FROM t4 )           }         integer 6
193206ce4136Sdan    8  { ( SELECT group_concat(y,'') FROM t4 ) }       text    onetwothree
193306ce4136Sdan    9  { ( SELECT max(x) FROM t4 WHERE y LIKE '___') } integer 2
193406ce4136Sdan
193506ce4136Sdan} {
193606ce4136Sdan  do_expr_test e_expr-36.3.$tn $expr $restype $resval
193706ce4136Sdan}
193806ce4136Sdan
193950da6635Sdrh# EVIDENCE-OF: R-52325-25449 The value of a subquery expression is NULL
194050da6635Sdrh# if the enclosed SELECT statement returns no rows.
194106ce4136Sdan#
194206ce4136Sdanforeach {tn expr} {
194306ce4136Sdan    1  { ( SELECT x FROM t4 WHERE x>3 ORDER BY x )      }
194406ce4136Sdan    2  { ( SELECT x FROM t4 WHERE y<'one' ORDER BY y )  }
194506ce4136Sdan} {
194606ce4136Sdan  do_expr_test e_expr-36.4.$tn $expr null {}
194706ce4136Sdan}
194806ce4136Sdan
19492c7e9bfcSdrh# EVIDENCE-OF: R-62477-06476 For example, the values NULL, 0.0, 0,
19502c7e9bfcSdrh# 'english' and '0' are all considered to be false.
19512c7e9bfcSdrh#
19522c7e9bfcSdrhdo_execsql_test e_expr-37.1 {
19533c0e606bSdrh   SELECT CASE WHEN NULL THEN 'true' ELSE 'false' END, iif(NULL,'true','false');
19543c0e606bSdrh} {false false}
19552c7e9bfcSdrhdo_execsql_test e_expr-37.2 {
19563c0e606bSdrh   SELECT CASE WHEN 0.0 THEN 'true' ELSE 'false' END, iif(0.0,'true','false');
19573c0e606bSdrh} {false false}
19582c7e9bfcSdrhdo_execsql_test e_expr-37.3 {
19593c0e606bSdrh   SELECT CASE WHEN 0 THEN 'true' ELSE 'false' END, iif(0,'true','false');
19603c0e606bSdrh} {false false}
19612c7e9bfcSdrhdo_execsql_test e_expr-37.4 {
19623c0e606bSdrh   SELECT CASE WHEN 'engligh' THEN 'true' ELSE 'false' END, iif('engligh','true','false');
19633c0e606bSdrh} {false false}
19642c7e9bfcSdrhdo_execsql_test e_expr-37.5 {
19653c0e606bSdrh   SELECT CASE WHEN '0' THEN 'true' ELSE 'false' END, iif('0','true','false');
19663c0e606bSdrh} {false false}
19672c7e9bfcSdrh
19682c7e9bfcSdrh# EVIDENCE-OF: R-55532-10108 Values 1, 1.0, 0.1, -0.1 and '1english' are
19692c7e9bfcSdrh# considered to be true.
19702c7e9bfcSdrh#
19712c7e9bfcSdrhdo_execsql_test e_expr-37.6 {
19723c0e606bSdrh   SELECT CASE WHEN 1 THEN 'true' ELSE 'false' END, iif(1,'true','false');
19733c0e606bSdrh} {true true}
19742c7e9bfcSdrhdo_execsql_test e_expr-37.7 {
19753c0e606bSdrh   SELECT CASE WHEN 1.0 THEN 'true' ELSE 'false' END, iif(1.0,'true','false');
19763c0e606bSdrh} {true true}
19772c7e9bfcSdrhdo_execsql_test e_expr-37.8 {
19783c0e606bSdrh   SELECT CASE WHEN 0.1 THEN 'true' ELSE 'false' END, iif(0.1,'true','false');
19793c0e606bSdrh} {true true}
19802c7e9bfcSdrhdo_execsql_test e_expr-37.9 {
19813c0e606bSdrh   SELECT CASE WHEN -0.1 THEN 'true' ELSE 'false' END, iif(-0.1,'true','false');
19823c0e606bSdrh} {true true}
19832c7e9bfcSdrhdo_execsql_test e_expr-37.10 {
19843c0e606bSdrh   SELECT CASE WHEN '1english' THEN 'true' ELSE 'false' END, iif('1engl','true','false');
19853c0e606bSdrh} {true true}
19862c7e9bfcSdrh
198706ce4136Sdan
198848d9e01eSdanfinish_test
1989