xref: /sqlite-3.40.0/test/e_expr.test (revision e8a537ee)
1784141eaSdan# 2010 July 16
2784141eaSdan#
3784141eaSdan# The author disclaims copyright to this source code.  In place of
4784141eaSdan# a legal notice, here is a blessing:
5784141eaSdan#
6784141eaSdan#    May you do good and not evil.
7784141eaSdan#    May you find forgiveness for yourself and forgive others.
8784141eaSdan#    May you share freely, never taking more than you give.
9784141eaSdan#
10784141eaSdan#***********************************************************************
11784141eaSdan#
12784141eaSdan# This file implements tests to verify that the "testable statements" in
13784141eaSdan# the lang_expr.html document are correct.
14784141eaSdan#
15784141eaSdan
16784141eaSdanset testdir [file dirname $argv0]
17784141eaSdansource $testdir/tester.tcl
18784141eaSdansource $testdir/malloc_common.tcl
19784141eaSdan
202f56da3fSdanifcapable !compound {
212f56da3fSdan  finish_test
222f56da3fSdan  return
232f56da3fSdan}
244336cc45Sdan
254336cc45Sdanproc do_expr_test {tn expr type value} {
264336cc45Sdan  uplevel do_execsql_test $tn [list "SELECT typeof($expr), $expr"] [
274336cc45Sdan    list [list $type $value]
284336cc45Sdan  ]
294336cc45Sdan}
304336cc45Sdan
314336cc45Sdanproc do_qexpr_test {tn expr value} {
324336cc45Sdan  uplevel do_execsql_test $tn [list "SELECT quote($expr)"] [list $value]
334336cc45Sdan}
344336cc45Sdan
35784141eaSdan# Set up three global variables:
36784141eaSdan#
37784141eaSdan#   ::opname         An array mapping from SQL operator to an easy to parse
38784141eaSdan#                    name. The names are used as part of test case names.
39784141eaSdan#
40784141eaSdan#   ::opprec         An array mapping from SQL operator to a numeric
41784141eaSdan#                    precedence value. Operators that group more tightly
42784141eaSdan#                    have lower numeric precedences.
43784141eaSdan#
44784141eaSdan#   ::oplist         A list of all SQL operators supported by SQLite.
45784141eaSdan#
46784141eaSdanforeach {op opn} {
47784141eaSdan      ||   cat     *   mul       /  div       %     mod       +      add
48784141eaSdan      -    sub     <<  lshift    >> rshift    &     bitand    |      bitor
49784141eaSdan      <    less    <=  lesseq    >  more      >=    moreeq    =      eq1
50784141eaSdan      ==   eq2     <>  ne1       != ne2       IS    is        LIKE   like
51784141eaSdan      GLOB glob    AND and       OR or        MATCH match     REGEXP regexp
52784141eaSdan      {IS NOT} isnt
53784141eaSdan} {
54784141eaSdan  set ::opname($op) $opn
55784141eaSdan}
56784141eaSdanset oplist [list]
57784141eaSdanforeach {prec opl} {
58784141eaSdan  1   ||
59784141eaSdan  2   {* / %}
60784141eaSdan  3   {+ -}
61784141eaSdan  4   {<< >> & |}
62784141eaSdan  5   {< <= > >=}
63784141eaSdan  6   {= == != <> IS {IS NOT} LIKE GLOB MATCH REGEXP}
64784141eaSdan  7   AND
65784141eaSdan  8   OR
66784141eaSdan} {
67784141eaSdan  foreach op $opl {
68784141eaSdan    set ::opprec($op) $prec
69784141eaSdan    lappend oplist $op
70784141eaSdan  }
71784141eaSdan}
72784141eaSdan
73784141eaSdan
74784141eaSdan# Hook in definitions of MATCH and REGEX. The following implementations
75784141eaSdan# cause MATCH and REGEX to behave similarly to the == operator.
76784141eaSdan#
77784141eaSdanproc matchfunc {a b} { return [expr {$a==$b}] }
78784141eaSdanproc regexfunc {a b} { return [expr {$a==$b}] }
79784141eaSdandb func match  -argcount 2 matchfunc
80784141eaSdandb func regexp -argcount 2 regexfunc
81784141eaSdan
82784141eaSdan#-------------------------------------------------------------------------
83784141eaSdan# Test cases e_expr-1.* attempt to verify that all binary operators listed
84784141eaSdan# in the documentation exist and that the relative precedences of the
85784141eaSdan# operators are also as the documentation suggests.
86784141eaSdan#
87784141eaSdan# EVIDENCE-OF: R-15514-65163 SQLite understands the following binary
88784141eaSdan# operators, in order from highest to lowest precedence: || * / % + -
89784141eaSdan# << >> & | < <= > >= = == != <> IS IS
90784141eaSdan# NOT IN LIKE GLOB MATCH REGEXP AND OR
91784141eaSdan#
92784141eaSdan# EVIDENCE-OF: R-38759-38789 Operators IS and IS NOT have the same
93784141eaSdan# precedence as =.
94784141eaSdan#
95784141eaSdan
96784141eaSdanunset -nocomplain untested
97784141eaSdanforeach op1 $oplist {
98784141eaSdan  foreach op2 $oplist {
99784141eaSdan    set untested($op1,$op2) 1
100784141eaSdan    foreach {tn A B C} {
101784141eaSdan       1     22   45    66
102784141eaSdan       2      0    0     0
103784141eaSdan       3      0    0     1
104784141eaSdan       4      0    1     0
105784141eaSdan       5      0    1     1
106784141eaSdan       6      1    0     0
107784141eaSdan       7      1    0     1
108784141eaSdan       8      1    1     0
109784141eaSdan       9      1    1     1
110784141eaSdan      10      5    6     1
111784141eaSdan      11      1    5     6
112784141eaSdan      12      1    5     5
113784141eaSdan      13      5    5     1
114784141eaSdan
115784141eaSdan      14      5    2     1
116784141eaSdan      15      1    4     1
117784141eaSdan      16     -1    0     1
118784141eaSdan      17      0    1    -1
119784141eaSdan
120784141eaSdan    } {
121784141eaSdan      set testname "e_expr-1.$opname($op1).$opname($op2).$tn"
122784141eaSdan
123784141eaSdan      # If $op2 groups more tightly than $op1, then the result
124784141eaSdan      # of executing $sql1 whould be the same as executing $sql3.
125784141eaSdan      # If $op1 groups more tightly, or if $op1 and $op2 have
126784141eaSdan      # the same precedence, then executing $sql1 should return
127784141eaSdan      # the same value as $sql2.
128784141eaSdan      #
129784141eaSdan      set sql1 "SELECT $A $op1 $B $op2 $C"
130784141eaSdan      set sql2 "SELECT ($A $op1 $B) $op2 $C"
131784141eaSdan      set sql3 "SELECT $A $op1 ($B $op2 $C)"
132784141eaSdan
133784141eaSdan      set a2 [db one $sql2]
134784141eaSdan      set a3 [db one $sql3]
135784141eaSdan
136784141eaSdan      do_execsql_test $testname $sql1 [list [
137bd0c0014Sdan        if {$opprec($op2) < $opprec($op1)} {set a3} {set a2}
138784141eaSdan      ]]
139784141eaSdan      if {$a2 != $a3} { unset -nocomplain untested($op1,$op2) }
140784141eaSdan    }
141784141eaSdan  }
142784141eaSdan}
143784141eaSdan
144784141eaSdanforeach op {* AND OR + || & |} { unset untested($op,$op) }
145784141eaSdanunset untested(+,-)  ;#       Since    (a+b)-c == a+(b-c)
146784141eaSdanunset untested(*,<<) ;#       Since    (a*b)<<c == a*(b<<c)
147784141eaSdan
148784141eaSdando_test e_expr-1.1 { array names untested } {}
149784141eaSdan
150784141eaSdan# At one point, test 1.2.2 was failing. Instead of the correct result, it
151784141eaSdan# was returning {1 1 0}. This would seem to indicate that LIKE has the
152784141eaSdan# same precedence as '<'. Which is incorrect. It has lower precedence.
153784141eaSdan#
154784141eaSdando_execsql_test e_expr-1.2.1 {
155784141eaSdan  SELECT 0 < 2 LIKE 1,   (0 < 2) LIKE 1,   0 < (2 LIKE 1)
156784141eaSdan} {1 1 0}
157784141eaSdando_execsql_test e_expr-1.2.2 {
158784141eaSdan  SELECT 0 LIKE 0 < 2,   (0 LIKE 0) < 2,   0 LIKE (0 < 2)
159784141eaSdan} {0 1 0}
160784141eaSdan
161784141eaSdan# Showing that LIKE and == have the same precedence
162784141eaSdan#
163784141eaSdando_execsql_test e_expr-1.2.3 {
164784141eaSdan  SELECT 2 LIKE 2 == 1,   (2 LIKE 2) == 1,    2 LIKE (2 == 1)
165784141eaSdan} {1 1 0}
166784141eaSdando_execsql_test e_expr-1.2.4 {
167784141eaSdan  SELECT 2 == 2 LIKE 1,   (2 == 2) LIKE 1,    2 == (2 LIKE 1)
168784141eaSdan} {1 1 0}
169784141eaSdan
170784141eaSdan# Showing that < groups more tightly than == (< has higher precedence).
171784141eaSdan#
172784141eaSdando_execsql_test e_expr-1.2.5 {
173784141eaSdan  SELECT 0 < 2 == 1,   (0 < 2) == 1,   0 < (2 == 1)
174784141eaSdan} {1 1 0}
175784141eaSdando_execsql_test e_expr-1.6 {
176784141eaSdan  SELECT 0 == 0 < 2,   (0 == 0) < 2,   0 == (0 < 2)
177784141eaSdan} {0 1 0}
178784141eaSdan
179784141eaSdan#-------------------------------------------------------------------------
180784141eaSdan# Check that the four unary prefix operators mentioned in the
181784141eaSdan# documentation exist.
182784141eaSdan#
183784141eaSdan# EVIDENCE-OF: R-13958-53419 Supported unary prefix operators are these:
184784141eaSdan# - + ~ NOT
185784141eaSdan#
186784141eaSdando_execsql_test e_expr-2.1 { SELECT -   10   } {-10}
187784141eaSdando_execsql_test e_expr-2.2 { SELECT +   10   } {10}
188784141eaSdando_execsql_test e_expr-2.3 { SELECT ~   10   } {-11}
189784141eaSdando_execsql_test e_expr-2.4 { SELECT NOT 10   } {0}
190784141eaSdan
191784141eaSdan#-------------------------------------------------------------------------
192784141eaSdan# Tests for the two statements made regarding the unary + operator.
193784141eaSdan#
194784141eaSdan# EVIDENCE-OF: R-53670-03373 The unary operator + is a no-op.
195784141eaSdan#
196784141eaSdan# EVIDENCE-OF: R-19480-30968 It can be applied to strings, numbers,
197784141eaSdan# blobs or NULL and it always returns a result with the same value as
198784141eaSdan# the operand.
199784141eaSdan#
200784141eaSdanforeach {tn literal type} {
201784141eaSdan  1     'helloworld'   text
202784141eaSdan  2     45             integer
203784141eaSdan  3     45.2           real
204784141eaSdan  4     45.0           real
205784141eaSdan  5     X'ABCDEF'      blob
206784141eaSdan  6     NULL           null
207784141eaSdan} {
208784141eaSdan  set sql " SELECT quote( + $literal ), typeof( + $literal) "
209784141eaSdan  do_execsql_test e_expr-3.$tn $sql [list $literal $type]
210784141eaSdan}
211784141eaSdan
212784141eaSdan#-------------------------------------------------------------------------
213784141eaSdan# Check that both = and == are both acceptable as the "equals" operator.
214784141eaSdan# Similarly, either != or <> work as the not-equals operator.
215784141eaSdan#
216784141eaSdan# EVIDENCE-OF: R-03679-60639 Equals can be either = or ==.
217784141eaSdan#
218784141eaSdan# EVIDENCE-OF: R-30082-38996 The non-equals operator can be either != or
219784141eaSdan# <>.
220784141eaSdan#
221784141eaSdanforeach {tn literal different} {
222784141eaSdan  1   'helloworld'  '12345'
223784141eaSdan  2   22            23
224784141eaSdan  3   'xyz'         X'78797A'
225784141eaSdan  4   X'78797A00'   'xyz'
226784141eaSdan} {
227784141eaSdan  do_execsql_test e_expr-4.$tn "
228784141eaSdan    SELECT $literal  = $literal,   $literal == $literal,
229784141eaSdan           $literal  = $different, $literal == $different,
230784141eaSdan           $literal  = NULL,       $literal == NULL,
231784141eaSdan           $literal != $literal,   $literal <> $literal,
232784141eaSdan           $literal != $different, $literal <> $different,
233784141eaSdan           $literal != NULL,       $literal != NULL
234784141eaSdan
235784141eaSdan  " {1 1 0 0 {} {} 0 0 1 1 {} {}}
236784141eaSdan}
237784141eaSdan
238784141eaSdan#-------------------------------------------------------------------------
239784141eaSdan# Test the || operator.
240784141eaSdan#
241784141eaSdan# EVIDENCE-OF: R-44409-62641 The || operator is "concatenate" - it joins
242784141eaSdan# together the two strings of its operands.
243784141eaSdan#
244784141eaSdanforeach {tn a b} {
245784141eaSdan  1   'helloworld'  '12345'
246784141eaSdan  2   22            23
247784141eaSdan} {
248784141eaSdan  set as [db one "SELECT $a"]
249784141eaSdan  set bs [db one "SELECT $b"]
250784141eaSdan
251784141eaSdan  do_execsql_test e_expr-5.$tn "SELECT $a || $b" [list "${as}${bs}"]
252784141eaSdan}
253784141eaSdan
254784141eaSdan#-------------------------------------------------------------------------
255784141eaSdan# Test the % operator.
256784141eaSdan#
257784141eaSdan# EVIDENCE-OF: R-08914-63790 The operator % outputs the value of its
258784141eaSdan# left operand modulo its right operand.
259784141eaSdan#
260784141eaSdando_execsql_test e_expr-6.1 {SELECT  72%5}  {2}
261784141eaSdando_execsql_test e_expr-6.2 {SELECT  72%-5} {2}
262784141eaSdando_execsql_test e_expr-6.3 {SELECT -72%-5} {-2}
263784141eaSdando_execsql_test e_expr-6.4 {SELECT -72%5}  {-2}
264784141eaSdan
265784141eaSdan#-------------------------------------------------------------------------
266784141eaSdan# Test that the results of all binary operators are either numeric or
267784141eaSdan# NULL, except for the || operator, which may evaluate to either a text
268784141eaSdan# value or NULL.
269784141eaSdan#
270784141eaSdan# EVIDENCE-OF: R-20665-17792 The result of any binary operator is either
271784141eaSdan# a numeric value or NULL, except for the || concatenation operator
272784141eaSdan# which always evaluates to either NULL or a text value.
273784141eaSdan#
274784141eaSdanset literals {
275784141eaSdan  1 'abc'        2 'hexadecimal'       3 ''
276784141eaSdan  4 123          5 -123                6 0
277784141eaSdan  7 123.4        8 0.0                 9 -123.4
278784141eaSdan 10 X'ABCDEF'   11 X''                12 X'0000'
279784141eaSdan 13     NULL
280784141eaSdan}
281784141eaSdanforeach op $oplist {
282784141eaSdan  foreach {n1 rhs} $literals {
283784141eaSdan  foreach {n2 lhs} $literals {
284784141eaSdan
285784141eaSdan    set t [db one " SELECT typeof($lhs $op $rhs) "]
286784141eaSdan    do_test e_expr-7.$opname($op).$n1.$n2 {
287784141eaSdan      expr {
288784141eaSdan           ($op=="||" && ($t == "text" || $t == "null"))
289784141eaSdan        || ($op!="||" && ($t == "integer" || $t == "real" || $t == "null"))
290784141eaSdan      }
291784141eaSdan    } 1
292784141eaSdan
293784141eaSdan  }}
294784141eaSdan}
295784141eaSdan
296784141eaSdan#-------------------------------------------------------------------------
297784141eaSdan# Test the IS and IS NOT operators.
298784141eaSdan#
299784141eaSdan# EVIDENCE-OF: R-24731-45773 The IS and IS NOT operators work like = and
300784141eaSdan# != except when one or both of the operands are NULL.
301784141eaSdan#
302784141eaSdan# EVIDENCE-OF: R-06325-15315 In this case, if both operands are NULL,
303784141eaSdan# then the IS operator evaluates to 1 (true) and the IS NOT operator
304784141eaSdan# evaluates to 0 (false).
305784141eaSdan#
306784141eaSdan# EVIDENCE-OF: R-19812-36779 If one operand is NULL and the other is
307784141eaSdan# not, then the IS operator evaluates to 0 (false) and the IS NOT
308784141eaSdan# operator is 1 (true).
309784141eaSdan#
310784141eaSdan# EVIDENCE-OF: R-61975-13410 It is not possible for an IS or IS NOT
311784141eaSdan# expression to evaluate to NULL.
312784141eaSdan#
313784141eaSdando_execsql_test e_expr-8.1.1  { SELECT NULL IS     NULL } {1}
314784141eaSdando_execsql_test e_expr-8.1.2  { SELECT 'ab' IS     NULL } {0}
315784141eaSdando_execsql_test e_expr-8.1.3  { SELECT NULL IS     'ab' } {0}
316784141eaSdando_execsql_test e_expr-8.1.4  { SELECT 'ab' IS     'ab' } {1}
317784141eaSdando_execsql_test e_expr-8.1.5  { SELECT NULL ==     NULL } {{}}
318784141eaSdando_execsql_test e_expr-8.1.6  { SELECT 'ab' ==     NULL } {{}}
319784141eaSdando_execsql_test e_expr-8.1.7  { SELECT NULL ==     'ab' } {{}}
320784141eaSdando_execsql_test e_expr-8.1.8  { SELECT 'ab' ==     'ab' } {1}
321784141eaSdando_execsql_test e_expr-8.1.9  { SELECT NULL IS NOT NULL } {0}
322784141eaSdando_execsql_test e_expr-8.1.10 { SELECT 'ab' IS NOT NULL } {1}
323784141eaSdando_execsql_test e_expr-8.1.11 { SELECT NULL IS NOT 'ab' } {1}
324784141eaSdando_execsql_test e_expr-8.1.12 { SELECT 'ab' IS NOT 'ab' } {0}
325784141eaSdando_execsql_test e_expr-8.1.13 { SELECT NULL !=     NULL } {{}}
326784141eaSdando_execsql_test e_expr-8.1.14 { SELECT 'ab' !=     NULL } {{}}
327784141eaSdando_execsql_test e_expr-8.1.15 { SELECT NULL !=     'ab' } {{}}
328784141eaSdando_execsql_test e_expr-8.1.16 { SELECT 'ab' !=     'ab' } {0}
329784141eaSdan
330784141eaSdanforeach {n1 rhs} $literals {
331784141eaSdan  foreach {n2 lhs} $literals {
332784141eaSdan    if {$rhs!="NULL" && $lhs!="NULL"} {
333784141eaSdan      set eq [execsql "SELECT $lhs = $rhs, $lhs != $rhs"]
334784141eaSdan    } else {
335784141eaSdan      set eq [list [expr {$lhs=="NULL" && $rhs=="NULL"}] \
336784141eaSdan                   [expr {$lhs!="NULL" || $rhs!="NULL"}]
337784141eaSdan      ]
338784141eaSdan    }
339784141eaSdan    set test e_expr-8.2.$n1.$n2
340784141eaSdan    do_execsql_test $test.1 "SELECT $lhs IS $rhs, $lhs IS NOT $rhs" $eq
341784141eaSdan    do_execsql_test $test.2 "
342784141eaSdan      SELECT ($lhs IS $rhs) IS NULL, ($lhs IS NOT $rhs) IS NULL
343784141eaSdan    " {0 0}
344784141eaSdan  }
345784141eaSdan}
346784141eaSdan
347c29486a2Sdan#-------------------------------------------------------------------------
348c29486a2Sdan# Run some tests on the COLLATE "unary postfix operator".
349c29486a2Sdan#
350c29486a2Sdan# This collation sequence reverses both arguments before using
351c29486a2Sdan# [string compare] to compare them. For example, when comparing the
352c29486a2Sdan# strings 'one' and 'four', return the result of:
353c29486a2Sdan#
354c29486a2Sdan#   string compare eno ruof
355c29486a2Sdan#
356c29486a2Sdanproc reverse_str {zStr} {
357c29486a2Sdan  set out ""
358c29486a2Sdan  foreach c [split $zStr {}] { set out "${c}${out}" }
359c29486a2Sdan  set out
360c29486a2Sdan}
361c29486a2Sdanproc reverse_collate {zLeft zRight} {
362c29486a2Sdan  string compare [reverse_str $zLeft] [reverse_str $zRight]
363c29486a2Sdan}
364c29486a2Sdandb collate reverse reverse_collate
365c29486a2Sdan
366c29486a2Sdan# EVIDENCE-OF: R-59577-33471 The COLLATE operator is a unary postfix
367c29486a2Sdan# operator that assigns a collating sequence to an expression.
368c29486a2Sdan#
36939759747Sdrh# EVIDENCE-OF: R-36231-30731 The COLLATE operator has a higher
37039759747Sdrh# precedence (binds more tightly) than any binary operator and any unary
37139759747Sdrh# prefix operator except "~".
372c29486a2Sdan#
373c29486a2Sdando_execsql_test e_expr-9.1 { SELECT  'abcd' < 'bbbb'    COLLATE reverse } 0
374c29486a2Sdando_execsql_test e_expr-9.2 { SELECT ('abcd' < 'bbbb')   COLLATE reverse } 1
375c29486a2Sdando_execsql_test e_expr-9.3 { SELECT  'abcd' <= 'bbbb'   COLLATE reverse } 0
376c29486a2Sdando_execsql_test e_expr-9.4 { SELECT ('abcd' <= 'bbbb')  COLLATE reverse } 1
377c29486a2Sdan
378c29486a2Sdando_execsql_test e_expr-9.5 { SELECT  'abcd' > 'bbbb'    COLLATE reverse } 1
379c29486a2Sdando_execsql_test e_expr-9.6 { SELECT ('abcd' > 'bbbb')   COLLATE reverse } 0
380c29486a2Sdando_execsql_test e_expr-9.7 { SELECT  'abcd' >= 'bbbb'   COLLATE reverse } 1
381c29486a2Sdando_execsql_test e_expr-9.8 { SELECT ('abcd' >= 'bbbb')  COLLATE reverse } 0
382c29486a2Sdan
383c29486a2Sdando_execsql_test e_expr-9.10 { SELECT  'abcd' =  'ABCD'  COLLATE nocase } 1
384c29486a2Sdando_execsql_test e_expr-9.11 { SELECT ('abcd' =  'ABCD') COLLATE nocase } 0
385c29486a2Sdando_execsql_test e_expr-9.12 { SELECT  'abcd' == 'ABCD'  COLLATE nocase } 1
386c29486a2Sdando_execsql_test e_expr-9.13 { SELECT ('abcd' == 'ABCD') COLLATE nocase } 0
387c29486a2Sdando_execsql_test e_expr-9.14 { SELECT  'abcd' IS 'ABCD'  COLLATE nocase } 1
388c29486a2Sdando_execsql_test e_expr-9.15 { SELECT ('abcd' IS 'ABCD') COLLATE nocase } 0
389c29486a2Sdan
390c29486a2Sdando_execsql_test e_expr-9.16 { SELECT  'abcd' != 'ABCD'      COLLATE nocase } 0
391c29486a2Sdando_execsql_test e_expr-9.17 { SELECT ('abcd' != 'ABCD')     COLLATE nocase } 1
392c29486a2Sdando_execsql_test e_expr-9.18 { SELECT  'abcd' <> 'ABCD'      COLLATE nocase } 0
393c29486a2Sdando_execsql_test e_expr-9.19 { SELECT ('abcd' <> 'ABCD')     COLLATE nocase } 1
394c29486a2Sdando_execsql_test e_expr-9.20 { SELECT  'abcd' IS NOT 'ABCD'  COLLATE nocase } 0
395c29486a2Sdando_execsql_test e_expr-9.21 { SELECT ('abcd' IS NOT 'ABCD') COLLATE nocase } 1
396c29486a2Sdan
397c29486a2Sdando_execsql_test e_expr-9.22 {
398c29486a2Sdan  SELECT 'bbb' BETWEEN 'AAA' AND 'CCC' COLLATE nocase
399c29486a2Sdan} 1
400c29486a2Sdando_execsql_test e_expr-9.23 {
401c29486a2Sdan  SELECT ('bbb' BETWEEN 'AAA' AND 'CCC') COLLATE nocase
402c29486a2Sdan} 0
403c29486a2Sdan
404c29486a2Sdan# EVIDENCE-OF: R-58731-25439 The collating sequence set by the COLLATE
405c29486a2Sdan# operator overrides the collating sequence determined by the COLLATE
406c29486a2Sdan# clause in a table column definition.
407c29486a2Sdan#
408c29486a2Sdando_execsql_test e_expr-9.24 {
409c29486a2Sdan  CREATE TABLE t24(a COLLATE NOCASE, b);
410c29486a2Sdan  INSERT INTO t24 VALUES('aaa', 1);
411c29486a2Sdan  INSERT INTO t24 VALUES('bbb', 2);
412c29486a2Sdan  INSERT INTO t24 VALUES('ccc', 3);
413c29486a2Sdan} {}
414c29486a2Sdando_execsql_test e_expr-9.25 { SELECT 'BBB' = a FROM t24 } {0 1 0}
415c29486a2Sdando_execsql_test e_expr-9.25 { SELECT a = 'BBB' FROM t24 } {0 1 0}
416c29486a2Sdando_execsql_test e_expr-9.25 { SELECT 'BBB' = a COLLATE binary FROM t24 } {0 0 0}
417c29486a2Sdando_execsql_test e_expr-9.25 { SELECT a COLLATE binary = 'BBB' FROM t24 } {0 0 0}
418c29486a2Sdan
419c29486a2Sdan#-------------------------------------------------------------------------
420c29486a2Sdan# Test statements related to literal values.
421c29486a2Sdan#
422c29486a2Sdan# EVIDENCE-OF: R-31536-32008 Literal values may be integers, floating
423c29486a2Sdan# point numbers, strings, BLOBs, or NULLs.
424c29486a2Sdan#
425c29486a2Sdando_execsql_test e_expr-10.1.1 { SELECT typeof(5)       } {integer}
426c29486a2Sdando_execsql_test e_expr-10.1.2 { SELECT typeof(5.1)     } {real}
427c29486a2Sdando_execsql_test e_expr-10.1.3 { SELECT typeof('5.1')   } {text}
428c29486a2Sdando_execsql_test e_expr-10.1.4 { SELECT typeof(X'ABCD') } {blob}
429c29486a2Sdando_execsql_test e_expr-10.1.5 { SELECT typeof(NULL)    } {null}
430c29486a2Sdan
43155f1da09Sdan# "Scientific notation is supported for point literal values."
432c29486a2Sdan#
433c29486a2Sdando_execsql_test e_expr-10.2.1 { SELECT typeof(3.4e-02)    } {real}
434c29486a2Sdando_execsql_test e_expr-10.2.2 { SELECT typeof(3e+5)       } {real}
435c29486a2Sdando_execsql_test e_expr-10.2.3 { SELECT 3.4e-02            } {0.034}
436c29486a2Sdando_execsql_test e_expr-10.2.4 { SELECT 3e+4               } {30000.0}
437c29486a2Sdan
438c29486a2Sdan# EVIDENCE-OF: R-35229-17830 A string constant is formed by enclosing
439c29486a2Sdan# the string in single quotes (').
440c29486a2Sdan#
441c29486a2Sdan# EVIDENCE-OF: R-07100-06606 A single quote within the string can be
442c29486a2Sdan# encoded by putting two single quotes in a row - as in Pascal.
443c29486a2Sdan#
444c29486a2Sdando_execsql_test e_expr-10.3.1 { SELECT 'is not' }         {{is not}}
445c29486a2Sdando_execsql_test e_expr-10.3.2 { SELECT typeof('is not') } {text}
446c29486a2Sdando_execsql_test e_expr-10.3.3 { SELECT 'isn''t' }         {isn't}
447c29486a2Sdando_execsql_test e_expr-10.3.4 { SELECT typeof('isn''t') } {text}
448c29486a2Sdan
449c29486a2Sdan# EVIDENCE-OF: R-09593-03321 BLOB literals are string literals
450c29486a2Sdan# containing hexadecimal data and preceded by a single "x" or "X"
451c29486a2Sdan# character.
452c29486a2Sdan#
453*e8a537eeSdrh# EVIDENCE-OF: R-19836-11244 Example: X'53514C697465'
454c29486a2Sdan#
455c29486a2Sdando_execsql_test e_expr-10.4.1 { SELECT typeof(X'0123456789ABCDEF') } blob
456c29486a2Sdando_execsql_test e_expr-10.4.2 { SELECT typeof(x'0123456789ABCDEF') } blob
457c29486a2Sdando_execsql_test e_expr-10.4.3 { SELECT typeof(X'0123456789abcdef') } blob
458c29486a2Sdando_execsql_test e_expr-10.4.4 { SELECT typeof(x'0123456789abcdef') } blob
459c29486a2Sdando_execsql_test e_expr-10.4.5 { SELECT typeof(X'53514C697465')     } blob
460c29486a2Sdan
461c29486a2Sdan# EVIDENCE-OF: R-23914-51476 A literal value can also be the token
462c29486a2Sdan# "NULL".
463c7d6156dSdan#
464c29486a2Sdando_execsql_test e_expr-10.5.1 { SELECT NULL         } {{}}
465c29486a2Sdando_execsql_test e_expr-10.5.2 { SELECT typeof(NULL) } {null}
466c29486a2Sdan
467c7d6156dSdan#-------------------------------------------------------------------------
468c7d6156dSdan# Test statements related to bound parameters
469c7d6156dSdan#
470c7d6156dSdan
471c7d6156dSdanproc parameter_test {tn sql params result} {
472c7d6156dSdan  set stmt [sqlite3_prepare_v2 db $sql -1]
473c7d6156dSdan
474c7d6156dSdan  foreach {number name} $params {
475c7d6156dSdan    set nm [sqlite3_bind_parameter_name $stmt $number]
476c7d6156dSdan    do_test $tn.name.$number [list set {} $nm] $name
477c7d6156dSdan    sqlite3_bind_int $stmt $number [expr -1 * $number]
478c7d6156dSdan  }
479c7d6156dSdan
480c7d6156dSdan  sqlite3_step $stmt
481c7d6156dSdan
482c7d6156dSdan  set res [list]
483c7d6156dSdan  for {set i 0} {$i < [sqlite3_column_count $stmt]} {incr i} {
484c7d6156dSdan    lappend res [sqlite3_column_text $stmt $i]
485c7d6156dSdan  }
486c7d6156dSdan
487c7d6156dSdan  set rc [sqlite3_finalize $stmt]
488c7d6156dSdan  do_test $tn.rc [list set {} $rc] SQLITE_OK
489c7d6156dSdan  do_test $tn.res [list set {} $res] $result
490c7d6156dSdan}
491c7d6156dSdan
492c7d6156dSdan# EVIDENCE-OF: R-33509-39458 A question mark followed by a number NNN
493c7d6156dSdan# holds a spot for the NNN-th parameter. NNN must be between 1 and
494c7d6156dSdan# SQLITE_MAX_VARIABLE_NUMBER.
495c7d6156dSdan#
496c7d6156dSdanset mvn $SQLITE_MAX_VARIABLE_NUMBER
497c7d6156dSdanparameter_test e_expr-11.1 "
498c7d6156dSdan  SELECT ?1, ?123, ?$SQLITE_MAX_VARIABLE_NUMBER, ?123, ?4
499c7d6156dSdan"   "1 ?1  123 ?123 $mvn ?$mvn 4 ?4"   "-1 -123 -$mvn -123 -4"
500c7d6156dSdan
501c7d6156dSdanset errmsg "variable number must be between ?1 and ?$SQLITE_MAX_VARIABLE_NUMBER"
502c7d6156dSdanforeach {tn param_number} [list \
503c7d6156dSdan  2  0                                    \
504c7d6156dSdan  3  [expr $SQLITE_MAX_VARIABLE_NUMBER+1] \
505c7d6156dSdan  4  [expr $SQLITE_MAX_VARIABLE_NUMBER+2] \
506c7d6156dSdan  5  12345678903456789034567890234567890  \
507c7d6156dSdan  6  2147483648                           \
508c7d6156dSdan  7  2147483649                           \
509c7d6156dSdan  8  4294967296                           \
510c7d6156dSdan  9  4294967297                           \
511c7d6156dSdan  10 9223372036854775808                  \
512c7d6156dSdan  11 9223372036854775809                  \
513c7d6156dSdan  12 18446744073709551616                 \
514c7d6156dSdan  13 18446744073709551617                 \
515c7d6156dSdan] {
516c7d6156dSdan  do_catchsql_test e_expr-11.1.$tn "SELECT ?$param_number" [list 1 $errmsg]
517c7d6156dSdan}
518c7d6156dSdan
519c7d6156dSdan# EVIDENCE-OF: R-33670-36097 A question mark that is not followed by a
520c7d6156dSdan# number creates a parameter with a number one greater than the largest
521c7d6156dSdan# parameter number already assigned.
522c7d6156dSdan#
523c7d6156dSdan# EVIDENCE-OF: R-42938-07030 If this means the parameter number is
524c7d6156dSdan# greater than SQLITE_MAX_VARIABLE_NUMBER, it is an error.
525c7d6156dSdan#
526c7d6156dSdanparameter_test e_expr-11.2.1 "SELECT ?"          {1 {}}       -1
527c7d6156dSdanparameter_test e_expr-11.2.2 "SELECT ?, ?"       {1 {} 2 {}}  {-1 -2}
528c7d6156dSdanparameter_test e_expr-11.2.3 "SELECT ?5, ?"      {5 ?5 6 {}}  {-5 -6}
529c7d6156dSdanparameter_test e_expr-11.2.4 "SELECT ?, ?5"      {1 {} 5 ?5}  {-1 -5}
530c7d6156dSdanparameter_test e_expr-11.2.5 "SELECT ?, ?456, ?" {
531c7d6156dSdan  1 {} 456 ?456 457 {}
532c7d6156dSdan}  {-1 -456 -457}
533c7d6156dSdanparameter_test e_expr-11.2.5 "SELECT ?, ?456, ?4, ?" {
534c7d6156dSdan  1 {} 456 ?456 4 ?4 457 {}
535c7d6156dSdan}  {-1 -456 -4 -457}
536c7d6156dSdanforeach {tn sql} [list                           \
537c7d6156dSdan  1  "SELECT ?$mvn, ?"                           \
538c7d6156dSdan  2  "SELECT ?[expr $mvn-5], ?, ?, ?, ?, ?, ?"   \
539c7d6156dSdan  3  "SELECT ?[expr $mvn], ?5, ?6, ?"            \
540c7d6156dSdan] {
541c7d6156dSdan  do_catchsql_test e_expr-11.3.$tn $sql [list 1 {too many SQL variables}]
542c7d6156dSdan}
543c7d6156dSdan
544c7d6156dSdan# EVIDENCE-OF: R-11620-22743 A colon followed by an identifier name
545c7d6156dSdan# holds a spot for a named parameter with the name :AAAA.
546c7d6156dSdan#
547c7d6156dSdan# Identifiers in SQLite consist of alphanumeric, '_' and '$' characters,
548c7d6156dSdan# and any UTF characters with codepoints larger than 127 (non-ASCII
549c7d6156dSdan# characters).
550c7d6156dSdan#
551c7d6156dSdanparameter_test e_expr-11.2.1 {SELECT :AAAA}         {1 :AAAA}       -1
552c7d6156dSdanparameter_test e_expr-11.2.2 {SELECT :123}          {1 :123}        -1
553c7d6156dSdanparameter_test e_expr-11.2.3 {SELECT :__}           {1 :__}         -1
554c7d6156dSdanparameter_test e_expr-11.2.4 {SELECT :_$_}          {1 :_$_}        -1
555c7d6156dSdanparameter_test e_expr-11.2.5 "
556c7d6156dSdan  SELECT :\u0e40\u0e2d\u0e28\u0e02\u0e39\u0e40\u0e2d\u0e25
557c7d6156dSdan" "1 :\u0e40\u0e2d\u0e28\u0e02\u0e39\u0e40\u0e2d\u0e25" -1
558c7d6156dSdanparameter_test e_expr-11.2.6 "SELECT :\u0080" "1 :\u0080" -1
559c7d6156dSdan
560c7d6156dSdan# EVIDENCE-OF: R-49783-61279 An "at" sign works exactly like a colon,
561c7d6156dSdan# except that the name of the parameter created is @AAAA.
562c7d6156dSdan#
563c7d6156dSdanparameter_test e_expr-11.3.1 {SELECT @AAAA}         {1 @AAAA}       -1
564c7d6156dSdanparameter_test e_expr-11.3.2 {SELECT @123}          {1 @123}        -1
565c7d6156dSdanparameter_test e_expr-11.3.3 {SELECT @__}           {1 @__}         -1
566c7d6156dSdanparameter_test e_expr-11.3.4 {SELECT @_$_}          {1 @_$_}        -1
567c7d6156dSdanparameter_test e_expr-11.3.5 "
568c7d6156dSdan  SELECT @\u0e40\u0e2d\u0e28\u0e02\u0e39\u0e40\u0e2d\u0e25
569c7d6156dSdan" "1 @\u0e40\u0e2d\u0e28\u0e02\u0e39\u0e40\u0e2d\u0e25" -1
570c7d6156dSdanparameter_test e_expr-11.3.6 "SELECT @\u0080" "1 @\u0080" -1
571c7d6156dSdan
572c7d6156dSdan# EVIDENCE-OF: R-62610-51329 A dollar-sign followed by an identifier
573c7d6156dSdan# name also holds a spot for a named parameter with the name $AAAA.
574c7d6156dSdan#
575c7d6156dSdan# EVIDENCE-OF: R-55025-21042 The identifier name in this case can
576c7d6156dSdan# include one or more occurrences of "::" and a suffix enclosed in
577c7d6156dSdan# "(...)" containing any text at all.
578c7d6156dSdan#
579c7d6156dSdan# Note: Looks like an identifier cannot consist entirely of "::"
580c7d6156dSdan# characters or just a suffix. Also, the other named variable characters
581c7d6156dSdan# (: and @) work the same way internally. Why not just document it that way?
582c7d6156dSdan#
583c7d6156dSdanparameter_test e_expr-11.4.1 {SELECT $AAAA}         {1 $AAAA}       -1
584c7d6156dSdanparameter_test e_expr-11.4.2 {SELECT $123}          {1 $123}        -1
585c7d6156dSdanparameter_test e_expr-11.4.3 {SELECT $__}           {1 $__}         -1
586c7d6156dSdanparameter_test e_expr-11.4.4 {SELECT $_$_}          {1 $_$_}        -1
587c7d6156dSdanparameter_test e_expr-11.4.5 "
588c7d6156dSdan  SELECT \$\u0e40\u0e2d\u0e28\u0e02\u0e39\u0e40\u0e2d\u0e25
589c7d6156dSdan" "1 \$\u0e40\u0e2d\u0e28\u0e02\u0e39\u0e40\u0e2d\u0e25" -1
590c7d6156dSdanparameter_test e_expr-11.4.6 "SELECT \$\u0080" "1 \$\u0080" -1
591c7d6156dSdan
592c7d6156dSdanparameter_test e_expr-11.5.1 {SELECT $::::a(++--++)} {1 $::::a(++--++)} -1
593c7d6156dSdanparameter_test e_expr-11.5.2 {SELECT $::a()} {1 $::a()} -1
594c7d6156dSdanparameter_test e_expr-11.5.3 {SELECT $::1(::#$)} {1 $::1(::#$)} -1
595c7d6156dSdan
596c7d6156dSdan# EVIDENCE-OF: R-11370-04520 Named parameters are also numbered. The
597c7d6156dSdan# number assigned is one greater than the largest parameter number
598c7d6156dSdan# already assigned.
599c7d6156dSdan#
600c7d6156dSdan# EVIDENCE-OF: R-42620-22184 If this means the parameter would be
601c7d6156dSdan# assigned a number greater than SQLITE_MAX_VARIABLE_NUMBER, it is an
602c7d6156dSdan# error.
603c7d6156dSdan#
604c7d6156dSdanparameter_test e_expr-11.6.1 "SELECT ?, @abc"    {1 {} 2 @abc} {-1 -2}
605c7d6156dSdanparameter_test e_expr-11.6.2 "SELECT ?123, :a1"  {123 ?123 124 :a1} {-123 -124}
606c7d6156dSdanparameter_test e_expr-11.6.3 {SELECT $a, ?8, ?, $b, ?2, $c} {
607c7d6156dSdan  1 $a 8 ?8 9 {} 10 $b 2 ?2 11 $c
608c7d6156dSdan} {-1 -8 -9 -10 -2 -11}
609c7d6156dSdanforeach {tn sql} [list                           \
610c7d6156dSdan  1  "SELECT ?$mvn, \$::a"                       \
611c7d6156dSdan  2  "SELECT ?$mvn, ?4, @a1"                     \
612c7d6156dSdan  3  "SELECT ?[expr $mvn-2], :bag, @123, \$x"    \
613c7d6156dSdan] {
614c7d6156dSdan  do_catchsql_test e_expr-11.7.$tn $sql [list 1 {too many SQL variables}]
615c7d6156dSdan}
616c7d6156dSdan
6171afca9b7Sdan# EVIDENCE-OF: R-14068-49671 Parameters that are not assigned values
6181afca9b7Sdan# using sqlite3_bind() are treated as NULL.
6191afca9b7Sdan#
6201afca9b7Sdando_test e_expr-11.7.1 {
6211afca9b7Sdan  set stmt [sqlite3_prepare_v2 db { SELECT ?, :a, @b, $d } -1]
6221afca9b7Sdan  sqlite3_step $stmt
6231afca9b7Sdan
6241afca9b7Sdan  list [sqlite3_column_type $stmt 0] \
6251afca9b7Sdan       [sqlite3_column_type $stmt 1] \
6261afca9b7Sdan       [sqlite3_column_type $stmt 2] \
6271afca9b7Sdan       [sqlite3_column_type $stmt 3]
6281afca9b7Sdan} {NULL NULL NULL NULL}
6291afca9b7Sdando_test e_expr-11.7.1 { sqlite3_finalize $stmt } SQLITE_OK
6301afca9b7Sdan
631994e9403Sdan#-------------------------------------------------------------------------
632994e9403Sdan# "Test" the syntax diagrams in lang_expr.html.
633994e9403Sdan#
63439759747Sdrh# -- syntax diagram signed-number
635994e9403Sdan#
636994e9403Sdando_execsql_test e_expr-12.1.1 { SELECT 0, +0, -0 } {0 0 0}
637994e9403Sdando_execsql_test e_expr-12.1.2 { SELECT 1, +1, -1 } {1 1 -1}
638994e9403Sdando_execsql_test e_expr-12.1.3 { SELECT 2, +2, -2 } {2 2 -2}
639994e9403Sdando_execsql_test e_expr-12.1.4 {
640994e9403Sdan  SELECT 1.4, +1.4, -1.4
641994e9403Sdan} {1.4 1.4 -1.4}
642994e9403Sdando_execsql_test e_expr-12.1.5 {
643994e9403Sdan  SELECT 1.5e+5, +1.5e+5, -1.5e+5
644994e9403Sdan} {150000.0 150000.0 -150000.0}
645994e9403Sdando_execsql_test e_expr-12.1.6 {
646994e9403Sdan  SELECT 0.0001, +0.0001, -0.0001
647994e9403Sdan} {0.0001 0.0001 -0.0001}
648994e9403Sdan
64939759747Sdrh# -- syntax diagram literal-value
650994e9403Sdan#
651994e9403Sdanset sqlite_current_time 1
652994e9403Sdando_execsql_test e_expr-12.2.1 {SELECT 123}               {123}
653994e9403Sdando_execsql_test e_expr-12.2.2 {SELECT 123.4e05}          {12340000.0}
654994e9403Sdando_execsql_test e_expr-12.2.3 {SELECT 'abcde'}           {abcde}
655994e9403Sdando_execsql_test e_expr-12.2.4 {SELECT X'414243'}         {ABC}
656994e9403Sdando_execsql_test e_expr-12.2.5 {SELECT NULL}              {{}}
657994e9403Sdando_execsql_test e_expr-12.2.6 {SELECT CURRENT_TIME}      {00:00:01}
658994e9403Sdando_execsql_test e_expr-12.2.7 {SELECT CURRENT_DATE}      {1970-01-01}
659994e9403Sdando_execsql_test e_expr-12.2.8 {SELECT CURRENT_TIMESTAMP} {{1970-01-01 00:00:01}}
660994e9403Sdanset sqlite_current_time 0
661994e9403Sdan
66239759747Sdrh# -- syntax diagram expr
663994e9403Sdan#
664fda06befSmistachkinforcedelete test.db2
665994e9403Sdanexecsql {
666994e9403Sdan  ATTACH 'test.db2' AS dbname;
667994e9403Sdan  CREATE TABLE dbname.tblname(cname);
668994e9403Sdan}
669994e9403Sdan
670994e9403Sdanproc glob {args} {return 1}
671994e9403Sdandb function glob glob
672994e9403Sdandb function match glob
673994e9403Sdandb function regexp glob
674994e9403Sdan
675994e9403Sdanforeach {tn expr} {
676994e9403Sdan  1 123
677994e9403Sdan  2 123.4e05
678994e9403Sdan  3 'abcde'
679994e9403Sdan  4 X'414243'
680994e9403Sdan  5 NULL
681994e9403Sdan  6 CURRENT_TIME
682994e9403Sdan  7 CURRENT_DATE
683994e9403Sdan  8 CURRENT_TIMESTAMP
684994e9403Sdan
685994e9403Sdan  9 ?
686994e9403Sdan 10 ?123
687994e9403Sdan 11 @hello
688994e9403Sdan 12 :world
689994e9403Sdan 13 $tcl
690994e9403Sdan 14 $tcl(array)
691994e9403Sdan
692994e9403Sdan  15 cname
693994e9403Sdan  16 tblname.cname
694994e9403Sdan  17 dbname.tblname.cname
695994e9403Sdan
696994e9403Sdan  18 "+ EXPR"
697994e9403Sdan  19 "- EXPR"
698994e9403Sdan  20 "NOT EXPR"
699994e9403Sdan  21 "~ EXPR"
700994e9403Sdan
701994e9403Sdan  22 "EXPR1 || EXPR2"
702994e9403Sdan  23 "EXPR1 * EXPR2"
703994e9403Sdan  24 "EXPR1 / EXPR2"
704994e9403Sdan  25 "EXPR1 % EXPR2"
705994e9403Sdan  26 "EXPR1 + EXPR2"
706994e9403Sdan  27 "EXPR1 - EXPR2"
707994e9403Sdan  28 "EXPR1 << EXPR2"
708994e9403Sdan  29 "EXPR1 >> EXPR2"
709994e9403Sdan  30 "EXPR1 & EXPR2"
710994e9403Sdan  31 "EXPR1 | EXPR2"
711994e9403Sdan  32 "EXPR1 < EXPR2"
712994e9403Sdan  33 "EXPR1 <= EXPR2"
713994e9403Sdan  34 "EXPR1 > EXPR2"
714994e9403Sdan  35 "EXPR1 >= EXPR2"
715994e9403Sdan  36 "EXPR1 = EXPR2"
716994e9403Sdan  37 "EXPR1 == EXPR2"
717994e9403Sdan  38 "EXPR1 != EXPR2"
718994e9403Sdan  39 "EXPR1 <> EXPR2"
719994e9403Sdan  40 "EXPR1 IS EXPR2"
720994e9403Sdan  41 "EXPR1 IS NOT EXPR2"
721994e9403Sdan  42 "EXPR1 AND EXPR2"
722994e9403Sdan  43 "EXPR1 OR EXPR2"
723994e9403Sdan
724994e9403Sdan  44 "count(*)"
725994e9403Sdan  45 "count(DISTINCT EXPR)"
726994e9403Sdan  46 "substr(EXPR, 10, 20)"
727994e9403Sdan  47 "changes()"
728994e9403Sdan
729994e9403Sdan  48 "( EXPR )"
730994e9403Sdan
731994e9403Sdan  49 "CAST ( EXPR AS integer )"
732994e9403Sdan  50 "CAST ( EXPR AS 'abcd' )"
733994e9403Sdan  51 "CAST ( EXPR AS 'ab$ $cd' )"
734994e9403Sdan
735994e9403Sdan  52 "EXPR COLLATE nocase"
736994e9403Sdan  53 "EXPR COLLATE binary"
737994e9403Sdan
738994e9403Sdan  54 "EXPR1 LIKE EXPR2"
739994e9403Sdan  55 "EXPR1 LIKE EXPR2 ESCAPE EXPR"
740994e9403Sdan  56 "EXPR1 GLOB EXPR2"
741994e9403Sdan  57 "EXPR1 GLOB EXPR2 ESCAPE EXPR"
742994e9403Sdan  58 "EXPR1 REGEXP EXPR2"
743994e9403Sdan  59 "EXPR1 REGEXP EXPR2 ESCAPE EXPR"
744994e9403Sdan  60 "EXPR1 MATCH EXPR2"
745994e9403Sdan  61 "EXPR1 MATCH EXPR2 ESCAPE EXPR"
746994e9403Sdan  62 "EXPR1 NOT LIKE EXPR2"
747994e9403Sdan  63 "EXPR1 NOT LIKE EXPR2 ESCAPE EXPR"
748994e9403Sdan  64 "EXPR1 NOT GLOB EXPR2"
749994e9403Sdan  65 "EXPR1 NOT GLOB EXPR2 ESCAPE EXPR"
750994e9403Sdan  66 "EXPR1 NOT REGEXP EXPR2"
751994e9403Sdan  67 "EXPR1 NOT REGEXP EXPR2 ESCAPE EXPR"
752994e9403Sdan  68 "EXPR1 NOT MATCH EXPR2"
753994e9403Sdan  69 "EXPR1 NOT MATCH EXPR2 ESCAPE EXPR"
754994e9403Sdan
755994e9403Sdan  70 "EXPR ISNULL"
756994e9403Sdan  71 "EXPR NOTNULL"
757994e9403Sdan  72 "EXPR NOT NULL"
758994e9403Sdan
759994e9403Sdan  73 "EXPR1 IS EXPR2"
760994e9403Sdan  74 "EXPR1 IS NOT EXPR2"
761994e9403Sdan
762994e9403Sdan  75 "EXPR NOT BETWEEN EXPR1 AND EXPR2"
763994e9403Sdan  76 "EXPR BETWEEN EXPR1 AND EXPR2"
764994e9403Sdan
765994e9403Sdan  77 "EXPR NOT IN (SELECT cname FROM tblname)"
766994e9403Sdan  78 "EXPR NOT IN (1)"
767994e9403Sdan  79 "EXPR NOT IN (1, 2, 3)"
768994e9403Sdan  80 "EXPR NOT IN tblname"
769994e9403Sdan  81 "EXPR NOT IN dbname.tblname"
770994e9403Sdan  82 "EXPR IN (SELECT cname FROM tblname)"
771994e9403Sdan  83 "EXPR IN (1)"
772994e9403Sdan  84 "EXPR IN (1, 2, 3)"
773994e9403Sdan  85 "EXPR IN tblname"
774994e9403Sdan  86 "EXPR IN dbname.tblname"
775994e9403Sdan
776994e9403Sdan  87 "EXISTS (SELECT cname FROM tblname)"
777994e9403Sdan  88 "NOT EXISTS (SELECT cname FROM tblname)"
778994e9403Sdan
779994e9403Sdan  89 "CASE EXPR WHEN EXPR1 THEN EXPR2 ELSE EXPR END"
780994e9403Sdan  90 "CASE EXPR WHEN EXPR1 THEN EXPR2 END"
781994e9403Sdan  91 "CASE EXPR WHEN EXPR1 THEN EXPR2 WHEN EXPR THEN EXPR1 ELSE EXPR2 END"
782994e9403Sdan  92 "CASE EXPR WHEN EXPR1 THEN EXPR2 WHEN EXPR THEN EXPR1 END"
783994e9403Sdan  93 "CASE WHEN EXPR1 THEN EXPR2 ELSE EXPR END"
784994e9403Sdan  94 "CASE WHEN EXPR1 THEN EXPR2 END"
785994e9403Sdan  95 "CASE WHEN EXPR1 THEN EXPR2 WHEN EXPR THEN EXPR1 ELSE EXPR2 END"
786994e9403Sdan  96 "CASE WHEN EXPR1 THEN EXPR2 WHEN EXPR THEN EXPR1 END"
787994e9403Sdan} {
788994e9403Sdan
789994e9403Sdan  # If the expression string being parsed contains "EXPR2", then replace
790994e9403Sdan  # string "EXPR1" and "EXPR2" with arbitrary SQL expressions. If it
791994e9403Sdan  # contains "EXPR", then replace EXPR with an arbitrary SQL expression.
792994e9403Sdan  #
793994e9403Sdan  set elist [list $expr]
794994e9403Sdan  if {[string match *EXPR2* $expr]} {
795994e9403Sdan    set elist [list]
796994e9403Sdan    foreach {e1 e2} { cname "34+22" } {
797994e9403Sdan      lappend elist [string map [list EXPR1 $e1 EXPR2 $e2] $expr]
798994e9403Sdan    }
799994e9403Sdan  }
800994e9403Sdan  if {[string match *EXPR* $expr]} {
801994e9403Sdan    set elist2 [list]
802994e9403Sdan    foreach el $elist {
803994e9403Sdan      foreach e { cname "34+22" } {
804994e9403Sdan        lappend elist2 [string map [list EXPR $e] $el]
805994e9403Sdan      }
806994e9403Sdan    }
807994e9403Sdan    set elist $elist2
808994e9403Sdan  }
809994e9403Sdan
810994e9403Sdan  set x 0
811994e9403Sdan  foreach e $elist {
812994e9403Sdan    incr x
813994e9403Sdan    do_test e_expr-12.3.$tn.$x {
814994e9403Sdan      set rc [catch { execsql "SELECT $e FROM tblname" } msg]
815994e9403Sdan    } {0}
816994e9403Sdan  }
817994e9403Sdan}
818994e9403Sdan
81939759747Sdrh# -- syntax diagram raise-function
820994e9403Sdan#
821994e9403Sdanforeach {tn raiseexpr} {
822994e9403Sdan  1 "RAISE(IGNORE)"
823994e9403Sdan  2 "RAISE(ROLLBACK, 'error message')"
824994e9403Sdan  3 "RAISE(ABORT, 'error message')"
825994e9403Sdan  4 "RAISE(FAIL, 'error message')"
826994e9403Sdan} {
827994e9403Sdan  do_execsql_test e_expr-12.4.$tn "
828994e9403Sdan    CREATE TRIGGER dbname.tr$tn BEFORE DELETE ON tblname BEGIN
829994e9403Sdan      SELECT $raiseexpr ;
830994e9403Sdan    END;
831994e9403Sdan  " {}
832994e9403Sdan}
833994e9403Sdan
83473625ec3Sdan#-------------------------------------------------------------------------
83573625ec3Sdan# Test the statements related to the BETWEEN operator.
83673625ec3Sdan#
83773625ec3Sdan# EVIDENCE-OF: R-40079-54503 The BETWEEN operator is logically
83873625ec3Sdan# equivalent to a pair of comparisons. "x BETWEEN y AND z" is equivalent
83973625ec3Sdan# to "x>=y AND x<=z" except that with BETWEEN, the x expression is
84073625ec3Sdan# only evaluated once.
84173625ec3Sdan#
84273625ec3Sdandb func x x
84373625ec3Sdanproc x {} { incr ::xcount ; return [expr $::x] }
84473625ec3Sdanforeach {tn x expr res nEval} {
84573625ec3Sdan  1  10  "x() >= 5 AND x() <= 15"  1  2
84673625ec3Sdan  2  10  "x() BETWEEN 5 AND 15"    1  1
84773625ec3Sdan
84873625ec3Sdan  3   5  "x() >= 5 AND x() <= 5"   1  2
84973625ec3Sdan  4   5  "x() BETWEEN 5 AND 5"     1  1
85073625ec3Sdan} {
85173625ec3Sdan  do_test e_expr-13.1.$tn {
85273625ec3Sdan    set ::xcount 0
85373625ec3Sdan    set a [execsql "SELECT $expr"]
85473625ec3Sdan    list $::xcount $a
85573625ec3Sdan  } [list $nEval $res]
85673625ec3Sdan}
85773625ec3Sdan
85873625ec3Sdan# EVIDENCE-OF: R-05155-34454 The precedence of the BETWEEN operator is
85973625ec3Sdan# the same as the precedence as operators == and != and LIKE and groups
86073625ec3Sdan# left to right.
86173625ec3Sdan#
86273625ec3Sdan# Therefore, BETWEEN groups more tightly than operator "AND", but less
86373625ec3Sdan# so than "<".
86473625ec3Sdan#
86573625ec3Sdando_execsql_test e_expr-13.2.1  { SELECT 1 == 10 BETWEEN 0 AND 2   }  1
86673625ec3Sdando_execsql_test e_expr-13.2.2  { SELECT (1 == 10) BETWEEN 0 AND 2 }  1
86773625ec3Sdando_execsql_test e_expr-13.2.3  { SELECT 1 == (10 BETWEEN 0 AND 2) }  0
86873625ec3Sdando_execsql_test e_expr-13.2.4  { SELECT  6 BETWEEN 4 AND 8 == 1 }    1
86973625ec3Sdando_execsql_test e_expr-13.2.5  { SELECT (6 BETWEEN 4 AND 8) == 1 }   1
87073625ec3Sdando_execsql_test e_expr-13.2.6  { SELECT  6 BETWEEN 4 AND (8 == 1) }  0
87173625ec3Sdan
87273625ec3Sdando_execsql_test e_expr-13.2.7  { SELECT  5 BETWEEN 0 AND 0  != 1 }   1
87373625ec3Sdando_execsql_test e_expr-13.2.8  { SELECT (5 BETWEEN 0 AND 0) != 1 }   1
87473625ec3Sdando_execsql_test e_expr-13.2.9  { SELECT  5 BETWEEN 0 AND (0 != 1) }  0
87573625ec3Sdando_execsql_test e_expr-13.2.10 { SELECT  1 != 0  BETWEEN 0 AND 2  }  1
87673625ec3Sdando_execsql_test e_expr-13.2.11 { SELECT (1 != 0) BETWEEN 0 AND 2  }  1
87773625ec3Sdando_execsql_test e_expr-13.2.12 { SELECT  1 != (0 BETWEEN 0 AND 2) }  0
87873625ec3Sdan
87973625ec3Sdando_execsql_test e_expr-13.2.13 { SELECT 1 LIKE 10 BETWEEN 0 AND 2   }  1
88073625ec3Sdando_execsql_test e_expr-13.2.14 { SELECT (1 LIKE 10) BETWEEN 0 AND 2 }  1
88173625ec3Sdando_execsql_test e_expr-13.2.15 { SELECT 1 LIKE (10 BETWEEN 0 AND 2) }  0
88273625ec3Sdando_execsql_test e_expr-13.2.16 { SELECT  6 BETWEEN 4 AND 8 LIKE 1   }  1
88373625ec3Sdando_execsql_test e_expr-13.2.17 { SELECT (6 BETWEEN 4 AND 8) LIKE 1  }  1
88473625ec3Sdando_execsql_test e_expr-13.2.18 { SELECT  6 BETWEEN 4 AND (8 LIKE 1) }  0
88573625ec3Sdan
88673625ec3Sdando_execsql_test e_expr-13.2.19 { SELECT 0 AND 0 BETWEEN 0 AND 1   } 0
88773625ec3Sdando_execsql_test e_expr-13.2.20 { SELECT 0 AND (0 BETWEEN 0 AND 1) } 0
88873625ec3Sdando_execsql_test e_expr-13.2.21 { SELECT (0 AND 0) BETWEEN 0 AND 1 } 1
88973625ec3Sdando_execsql_test e_expr-13.2.22 { SELECT 0 BETWEEN -1 AND 1 AND 0   } 0
89073625ec3Sdando_execsql_test e_expr-13.2.23 { SELECT (0 BETWEEN -1 AND 1) AND 0 } 0
89173625ec3Sdando_execsql_test e_expr-13.2.24 { SELECT 0 BETWEEN -1 AND (1 AND 0) } 1
89273625ec3Sdan
89373625ec3Sdando_execsql_test e_expr-13.2.25 { SELECT 2 < 3 BETWEEN 0 AND 1   } 1
89473625ec3Sdando_execsql_test e_expr-13.2.26 { SELECT (2 < 3) BETWEEN 0 AND 1 } 1
89573625ec3Sdando_execsql_test e_expr-13.2.27 { SELECT 2 < (3 BETWEEN 0 AND 1) } 0
89673625ec3Sdando_execsql_test e_expr-13.2.28 { SELECT 2 BETWEEN 1 AND 2 < 3    } 0
89773625ec3Sdando_execsql_test e_expr-13.2.29 { SELECT 2 BETWEEN 1 AND (2 < 3)  } 0
89873625ec3Sdando_execsql_test e_expr-13.2.30 { SELECT (2 BETWEEN 1 AND 2) < 3  } 1
899f5d3df40Sdan
900f5d3df40Sdan#-------------------------------------------------------------------------
901f5d3df40Sdan# Test the statements related to the LIKE and GLOB operators.
902f5d3df40Sdan#
903f5d3df40Sdan# EVIDENCE-OF: R-16584-60189 The LIKE operator does a pattern matching
904f5d3df40Sdan# comparison.
905f5d3df40Sdan#
906f5d3df40Sdan# EVIDENCE-OF: R-11295-04657 The operand to the right of the LIKE
907f5d3df40Sdan# operator contains the pattern and the left hand operand contains the
908f5d3df40Sdan# string to match against the pattern.
909f5d3df40Sdan#
910f5d3df40Sdando_execsql_test e_expr-14.1.1 { SELECT 'abc%' LIKE 'abcde' } 0
911f5d3df40Sdando_execsql_test e_expr-14.1.2 { SELECT 'abcde' LIKE 'abc%' } 1
912f5d3df40Sdan
913f5d3df40Sdan# EVIDENCE-OF: R-55406-38524 A percent symbol ("%") in the LIKE pattern
914f5d3df40Sdan# matches any sequence of zero or more characters in the string.
915f5d3df40Sdan#
916f5d3df40Sdando_execsql_test e_expr-14.2.1 { SELECT 'abde'    LIKE 'ab%de' } 1
917f5d3df40Sdando_execsql_test e_expr-14.2.2 { SELECT 'abXde'   LIKE 'ab%de' } 1
918f5d3df40Sdando_execsql_test e_expr-14.2.3 { SELECT 'abABCde' LIKE 'ab%de' } 1
919f5d3df40Sdan
920f5d3df40Sdan# EVIDENCE-OF: R-30433-25443 An underscore ("_") in the LIKE pattern
921f5d3df40Sdan# matches any single character in the string.
922f5d3df40Sdan#
923f5d3df40Sdando_execsql_test e_expr-14.3.1 { SELECT 'abde'    LIKE 'ab_de' } 0
924f5d3df40Sdando_execsql_test e_expr-14.3.2 { SELECT 'abXde'   LIKE 'ab_de' } 1
925f5d3df40Sdando_execsql_test e_expr-14.3.3 { SELECT 'abABCde' LIKE 'ab_de' } 0
926f5d3df40Sdan
927f5d3df40Sdan# EVIDENCE-OF: R-59007-20454 Any other character matches itself or its
928f5d3df40Sdan# lower/upper case equivalent (i.e. case-insensitive matching).
929f5d3df40Sdan#
930f5d3df40Sdando_execsql_test e_expr-14.4.1 { SELECT 'abc' LIKE 'aBc' } 1
931f5d3df40Sdando_execsql_test e_expr-14.4.2 { SELECT 'aBc' LIKE 'aBc' } 1
932f5d3df40Sdando_execsql_test e_expr-14.4.3 { SELECT 'ac'  LIKE 'aBc' } 0
933f5d3df40Sdan
934f5d3df40Sdan# EVIDENCE-OF: R-23648-58527 SQLite only understands upper/lower case
935f5d3df40Sdan# for ASCII characters by default.
936f5d3df40Sdan#
937f5d3df40Sdan# EVIDENCE-OF: R-04532-11527 The LIKE operator is case sensitive by
938f5d3df40Sdan# default for unicode characters that are beyond the ASCII range.
939f5d3df40Sdan#
940f5d3df40Sdan# EVIDENCE-OF: R-44381-11669 the expression
941f5d3df40Sdan# 'a'&nbsp;LIKE&nbsp;'A' is TRUE but
942f5d3df40Sdan# '&aelig;'&nbsp;LIKE&nbsp;'&AElig;' is FALSE.
943f5d3df40Sdan#
9446bd2c735Sdan#   The restriction to ASCII characters does not apply if the ICU
9456bd2c735Sdan#   library is compiled in. When ICU is enabled SQLite does not act
9466bd2c735Sdan#   as it does "by default".
9476bd2c735Sdan#
948f5d3df40Sdando_execsql_test e_expr-14.5.1 { SELECT 'A' LIKE 'a'         } 1
9496bd2c735Sdanifcapable !icu {
950f5d3df40Sdan  do_execsql_test e_expr-14.5.2 "SELECT '\u00c6' LIKE '\u00e6'" 0
9516bd2c735Sdan}
952f5d3df40Sdan
953f5d3df40Sdan# EVIDENCE-OF: R-56683-13731 If the optional ESCAPE clause is present,
954f5d3df40Sdan# then the expression following the ESCAPE keyword must evaluate to a
955f5d3df40Sdan# string consisting of a single character.
956f5d3df40Sdan#
957f5d3df40Sdando_catchsql_test e_expr-14.6.1 {
958f5d3df40Sdan  SELECT 'A' LIKE 'a' ESCAPE '12'
959f5d3df40Sdan} {1 {ESCAPE expression must be a single character}}
960f5d3df40Sdando_catchsql_test e_expr-14.6.2 {
961f5d3df40Sdan  SELECT 'A' LIKE 'a' ESCAPE ''
962f5d3df40Sdan} {1 {ESCAPE expression must be a single character}}
963f5d3df40Sdando_catchsql_test e_expr-14.6.3 { SELECT 'A' LIKE 'a' ESCAPE 'x' }    {0 1}
964f5d3df40Sdando_catchsql_test e_expr-14.6.4 "SELECT 'A' LIKE 'a' ESCAPE '\u00e6'" {0 1}
965f5d3df40Sdan
966f5d3df40Sdan# EVIDENCE-OF: R-02045-23762 This character may be used in the LIKE
967f5d3df40Sdan# pattern to include literal percent or underscore characters.
968f5d3df40Sdan#
969f5d3df40Sdan# EVIDENCE-OF: R-13345-31830 The escape character followed by a percent
970f5d3df40Sdan# symbol (%), underscore (_), or a second instance of the escape
971f5d3df40Sdan# character itself matches a literal percent symbol, underscore, or a
972f5d3df40Sdan# single escape character, respectively.
973f5d3df40Sdan#
974f5d3df40Sdando_execsql_test e_expr-14.7.1  { SELECT 'abc%'  LIKE 'abcX%' ESCAPE 'X' } 1
975f5d3df40Sdando_execsql_test e_expr-14.7.2  { SELECT 'abc5'  LIKE 'abcX%' ESCAPE 'X' } 0
976f5d3df40Sdando_execsql_test e_expr-14.7.3  { SELECT 'abc'   LIKE 'abcX%' ESCAPE 'X' } 0
977f5d3df40Sdando_execsql_test e_expr-14.7.4  { SELECT 'abcX%' LIKE 'abcX%' ESCAPE 'X' } 0
978f5d3df40Sdando_execsql_test e_expr-14.7.5  { SELECT 'abc%%' LIKE 'abcX%' ESCAPE 'X' } 0
979f5d3df40Sdan
980f5d3df40Sdando_execsql_test e_expr-14.7.6  { SELECT 'abc_'  LIKE 'abcX_' ESCAPE 'X' } 1
981f5d3df40Sdando_execsql_test e_expr-14.7.7  { SELECT 'abc5'  LIKE 'abcX_' ESCAPE 'X' } 0
982f5d3df40Sdando_execsql_test e_expr-14.7.8  { SELECT 'abc'   LIKE 'abcX_' ESCAPE 'X' } 0
983f5d3df40Sdando_execsql_test e_expr-14.7.9  { SELECT 'abcX_' LIKE 'abcX_' ESCAPE 'X' } 0
984f5d3df40Sdando_execsql_test e_expr-14.7.10 { SELECT 'abc__' LIKE 'abcX_' ESCAPE 'X' } 0
985f5d3df40Sdan
986f5d3df40Sdando_execsql_test e_expr-14.7.11 { SELECT 'abcX'  LIKE 'abcXX' ESCAPE 'X' } 1
987f5d3df40Sdando_execsql_test e_expr-14.7.12 { SELECT 'abc5'  LIKE 'abcXX' ESCAPE 'X' } 0
988f5d3df40Sdando_execsql_test e_expr-14.7.13 { SELECT 'abc'   LIKE 'abcXX' ESCAPE 'X' } 0
989f5d3df40Sdando_execsql_test e_expr-14.7.14 { SELECT 'abcXX' LIKE 'abcXX' ESCAPE 'X' } 0
990f5d3df40Sdan
991f5d3df40Sdan# EVIDENCE-OF: R-51359-17496 The infix LIKE operator is implemented by
992f5d3df40Sdan# calling the application-defined SQL functions like(Y,X) or like(Y,X,Z).
993f5d3df40Sdan#
994f5d3df40Sdanproc likefunc {args} {
995f5d3df40Sdan  eval lappend ::likeargs $args
996f5d3df40Sdan  return 1
997f5d3df40Sdan}
9986bd2c735Sdandb func like -argcount 2 likefunc
9996bd2c735Sdandb func like -argcount 3 likefunc
1000f5d3df40Sdanset ::likeargs [list]
1001f5d3df40Sdando_execsql_test e_expr-15.1.1 { SELECT 'abc' LIKE 'def' } 1
1002f5d3df40Sdando_test         e_expr-15.1.2 { set likeargs } {def abc}
1003f5d3df40Sdanset ::likeargs [list]
1004f5d3df40Sdando_execsql_test e_expr-15.1.3 { SELECT 'abc' LIKE 'def' ESCAPE 'X' } 1
1005f5d3df40Sdando_test         e_expr-15.1.4 { set likeargs } {def abc X}
1006f5d3df40Sdandb close
1007f5d3df40Sdansqlite3 db test.db
1008f5d3df40Sdan
1009f5d3df40Sdan# EVIDENCE-OF: R-22868-25880 The LIKE operator can be made case
1010f5d3df40Sdan# sensitive using the case_sensitive_like pragma.
1011f5d3df40Sdan#
1012f5d3df40Sdando_execsql_test e_expr-16.1.1 { SELECT 'abcxyz' LIKE 'ABC%' } 1
1013f5d3df40Sdando_execsql_test e_expr-16.1.2 { PRAGMA case_sensitive_like = 1 } {}
1014f5d3df40Sdando_execsql_test e_expr-16.1.3 { SELECT 'abcxyz' LIKE 'ABC%' } 0
1015f5d3df40Sdando_execsql_test e_expr-16.1.4 { SELECT 'ABCxyz' LIKE 'ABC%' } 1
1016f5d3df40Sdando_execsql_test e_expr-16.1.5 { PRAGMA case_sensitive_like = 0 } {}
1017f5d3df40Sdando_execsql_test e_expr-16.1.6 { SELECT 'abcxyz' LIKE 'ABC%' } 1
1018f5d3df40Sdando_execsql_test e_expr-16.1.7 { SELECT 'ABCxyz' LIKE 'ABC%' } 1
1019f5d3df40Sdan
1020f5d3df40Sdan# EVIDENCE-OF: R-52087-12043 The GLOB operator is similar to LIKE but
1021f5d3df40Sdan# uses the Unix file globbing syntax for its wildcards.
1022f5d3df40Sdan#
1023f5d3df40Sdan# EVIDENCE-OF: R-09813-17279 Also, GLOB is case sensitive, unlike LIKE.
1024f5d3df40Sdan#
1025f5d3df40Sdando_execsql_test e_expr-17.1.1 { SELECT 'abcxyz' GLOB 'abc%' } 0
1026f5d3df40Sdando_execsql_test e_expr-17.1.2 { SELECT 'abcxyz' GLOB 'abc*' } 1
1027f5d3df40Sdando_execsql_test e_expr-17.1.3 { SELECT 'abcxyz' GLOB 'abc___' } 0
1028f5d3df40Sdando_execsql_test e_expr-17.1.4 { SELECT 'abcxyz' GLOB 'abc???' } 1
1029f5d3df40Sdan
1030f5d3df40Sdando_execsql_test e_expr-17.1.5 { SELECT 'abcxyz' GLOB 'abc*' } 1
1031f5d3df40Sdando_execsql_test e_expr-17.1.6 { SELECT 'ABCxyz' GLOB 'abc*' } 0
1032f5d3df40Sdando_execsql_test e_expr-17.1.7 { SELECT 'abcxyz' GLOB 'ABC*' } 0
1033f5d3df40Sdan
1034f5d3df40Sdan# EVIDENCE-OF: R-39616-20555 Both GLOB and LIKE may be preceded by the
1035f5d3df40Sdan# NOT keyword to invert the sense of the test.
1036f5d3df40Sdan#
1037f5d3df40Sdando_execsql_test e_expr-17.2.1 { SELECT 'abcxyz' NOT GLOB 'ABC*' } 1
1038f5d3df40Sdando_execsql_test e_expr-17.2.2 { SELECT 'abcxyz' NOT GLOB 'abc*' } 0
1039f5d3df40Sdando_execsql_test e_expr-17.2.3 { SELECT 'abcxyz' NOT LIKE 'ABC%' } 0
1040f5d3df40Sdando_execsql_test e_expr-17.2.4 { SELECT 'abcxyz' NOT LIKE 'abc%' } 0
1041f5d3df40Sdando_execsql_test e_expr-17.2.5 { SELECT 'abdxyz' NOT LIKE 'abc%' } 1
1042f5d3df40Sdan
1043f5d3df40Sdandb nullvalue null
1044f5d3df40Sdando_execsql_test e_expr-17.2.6 { SELECT 'abcxyz' NOT GLOB NULL } null
1045f5d3df40Sdando_execsql_test e_expr-17.2.7 { SELECT 'abcxyz' NOT LIKE NULL } null
1046f5d3df40Sdando_execsql_test e_expr-17.2.8 { SELECT NULL NOT GLOB 'abc*' } null
1047f5d3df40Sdando_execsql_test e_expr-17.2.9 { SELECT NULL NOT LIKE 'ABC%' } null
1048f5d3df40Sdandb nullvalue {}
1049f5d3df40Sdan
1050f5d3df40Sdan# EVIDENCE-OF: R-39414-35489 The infix GLOB operator is implemented by
1051f5d3df40Sdan# calling the function glob(Y,X) and can be modified by overriding that
1052f5d3df40Sdan# function.
1053f5d3df40Sdanproc globfunc {args} {
1054f5d3df40Sdan  eval lappend ::globargs $args
1055f5d3df40Sdan  return 1
1056f5d3df40Sdan}
1057f5d3df40Sdandb func glob -argcount 2 globfunc
1058f5d3df40Sdanset ::globargs [list]
1059f5d3df40Sdando_execsql_test e_expr-17.3.1 { SELECT 'abc' GLOB 'def' } 1
1060f5d3df40Sdando_test         e_expr-17.3.2 { set globargs } {def abc}
1061f5d3df40Sdanset ::globargs [list]
1062f5d3df40Sdando_execsql_test e_expr-17.3.3 { SELECT 'X' NOT GLOB 'Y' } 0
1063f5d3df40Sdando_test         e_expr-17.3.4 { set globargs } {Y X}
1064f5d3df40Sdansqlite3 db test.db
1065f5d3df40Sdan
1066f5d3df40Sdan# EVIDENCE-OF: R-41650-20872 No regexp() user function is defined by
1067f5d3df40Sdan# default and so use of the REGEXP operator will normally result in an
1068f5d3df40Sdan# error message.
1069f5d3df40Sdan#
10706bd2c735Sdan#   There is a regexp function if ICU is enabled though.
10716bd2c735Sdan#
10726bd2c735Sdanifcapable !icu {
1073f5d3df40Sdan  do_catchsql_test e_expr-18.1.1 {
1074f5d3df40Sdan    SELECT regexp('abc', 'def')
1075f5d3df40Sdan  } {1 {no such function: regexp}}
1076f5d3df40Sdan  do_catchsql_test e_expr-18.1.2 {
1077f5d3df40Sdan    SELECT 'abc' REGEXP 'def'
1078f5d3df40Sdan  } {1 {no such function: REGEXP}}
10796bd2c735Sdan}
1080f5d3df40Sdan
1081f5d3df40Sdan# EVIDENCE-OF: R-33693-50180 The REGEXP operator is a special syntax for
1082f5d3df40Sdan# the regexp() user function.
1083f5d3df40Sdan#
1084f37139f6Sdrh# EVIDENCE-OF: R-65524-61849 If an application-defined SQL function
1085f37139f6Sdrh# named "regexp" is added at run-time, then the "X REGEXP Y" operator
1086f37139f6Sdrh# will be implemented as a call to "regexp(Y,X)".
1087f5d3df40Sdan#
1088f5d3df40Sdanproc regexpfunc {args} {
1089f5d3df40Sdan  eval lappend ::regexpargs $args
1090f5d3df40Sdan  return 1
1091f5d3df40Sdan}
1092f5d3df40Sdandb func regexp -argcount 2 regexpfunc
1093f5d3df40Sdanset ::regexpargs [list]
1094f5d3df40Sdando_execsql_test e_expr-18.2.1 { SELECT 'abc' REGEXP 'def' } 1
1095f5d3df40Sdando_test         e_expr-18.2.2 { set regexpargs } {def abc}
1096f5d3df40Sdanset ::regexpargs [list]
1097f5d3df40Sdando_execsql_test e_expr-18.2.3 { SELECT 'X' NOT REGEXP 'Y' } 0
1098f5d3df40Sdando_test         e_expr-18.2.4 { set regexpargs } {Y X}
1099f5d3df40Sdansqlite3 db test.db
1100f5d3df40Sdan
1101f5d3df40Sdan# EVIDENCE-OF: R-42037-37826 The default match() function implementation
1102f5d3df40Sdan# raises an exception and is not really useful for anything.
1103f5d3df40Sdan#
1104f5d3df40Sdando_catchsql_test e_expr-19.1.1 {
1105f5d3df40Sdan  SELECT 'abc' MATCH 'def'
1106f5d3df40Sdan} {1 {unable to use function MATCH in the requested context}}
1107f5d3df40Sdando_catchsql_test e_expr-19.1.2 {
1108f5d3df40Sdan  SELECT match('abc', 'def')
1109f5d3df40Sdan} {1 {unable to use function MATCH in the requested context}}
1110f5d3df40Sdan
1111f5d3df40Sdan# EVIDENCE-OF: R-37916-47407 The MATCH operator is a special syntax for
1112f5d3df40Sdan# the match() application-defined function.
1113f5d3df40Sdan#
1114f5d3df40Sdan# EVIDENCE-OF: R-06021-09373 But extensions can override the match()
1115f5d3df40Sdan# function with more helpful logic.
1116f5d3df40Sdan#
1117f5d3df40Sdanproc matchfunc {args} {
1118f5d3df40Sdan  eval lappend ::matchargs $args
1119f5d3df40Sdan  return 1
1120f5d3df40Sdan}
1121f5d3df40Sdandb func match -argcount 2 matchfunc
1122f5d3df40Sdanset ::matchargs [list]
1123f5d3df40Sdando_execsql_test e_expr-19.2.1 { SELECT 'abc' MATCH 'def' } 1
1124f5d3df40Sdando_test         e_expr-19.2.2 { set matchargs } {def abc}
1125f5d3df40Sdanset ::matchargs [list]
1126f5d3df40Sdando_execsql_test e_expr-19.2.3 { SELECT 'X' NOT MATCH 'Y' } 0
1127f5d3df40Sdando_test         e_expr-19.2.4 { set matchargs } {Y X}
1128f5d3df40Sdansqlite3 db test.db
1129f5d3df40Sdan
1130eb385b40Sdan#-------------------------------------------------------------------------
1131eb385b40Sdan# Test cases for the testable statements related to the CASE expression.
1132eb385b40Sdan#
1133eb385b40Sdan# EVIDENCE-OF: R-15199-61389 There are two basic forms of the CASE
1134eb385b40Sdan# expression: those with a base expression and those without.
1135eb385b40Sdan#
1136eb385b40Sdando_execsql_test e_expr-20.1 {
1137eb385b40Sdan  SELECT CASE WHEN 1 THEN 'true' WHEN 0 THEN 'false' ELSE 'else' END;
1138eb385b40Sdan} {true}
1139eb385b40Sdando_execsql_test e_expr-20.2 {
1140eb385b40Sdan  SELECT CASE 0 WHEN 1 THEN 'true' WHEN 0 THEN 'false' ELSE 'else' END;
1141eb385b40Sdan} {false}
1142eb385b40Sdan
1143eb385b40Sdanproc var {nm} {
1144eb385b40Sdan  lappend ::varlist $nm
1145eb385b40Sdan  return [set "::$nm"]
1146eb385b40Sdan}
1147eb385b40Sdandb func var var
1148eb385b40Sdan
1149eb385b40Sdan# EVIDENCE-OF: R-30638-59954 In a CASE without a base expression, each
1150eb385b40Sdan# WHEN expression is evaluated and the result treated as a boolean,
1151eb385b40Sdan# starting with the leftmost and continuing to the right.
1152eb385b40Sdan#
1153eb385b40Sdanforeach {a b c} {0 0 0} break
1154eb385b40Sdanset varlist [list]
1155eb385b40Sdando_execsql_test e_expr-21.1.1 {
1156eb385b40Sdan  SELECT CASE WHEN var('a') THEN 'A'
1157eb385b40Sdan              WHEN var('b') THEN 'B'
1158eb385b40Sdan              WHEN var('c') THEN 'C' END
1159eb385b40Sdan} {{}}
1160eb385b40Sdando_test e_expr-21.1.2 { set varlist } {a b c}
1161eb385b40Sdanset varlist [list]
1162eb385b40Sdando_execsql_test e_expr-21.1.3 {
1163eb385b40Sdan  SELECT CASE WHEN var('c') THEN 'C'
1164eb385b40Sdan              WHEN var('b') THEN 'B'
1165eb385b40Sdan              WHEN var('a') THEN 'A'
1166eb385b40Sdan              ELSE 'no result'
1167eb385b40Sdan  END
1168eb385b40Sdan} {{no result}}
1169eb385b40Sdando_test e_expr-21.1.4 { set varlist } {c b a}
1170eb385b40Sdan
1171eb385b40Sdan# EVIDENCE-OF: R-39009-25596 The result of the CASE expression is the
1172eb385b40Sdan# evaluation of the THEN expression that corresponds to the first WHEN
1173eb385b40Sdan# expression that evaluates to true.
1174eb385b40Sdan#
1175eb385b40Sdanforeach {a b c} {0 1 0} break
1176eb385b40Sdando_execsql_test e_expr-21.2.1 {
1177eb385b40Sdan  SELECT CASE WHEN var('a') THEN 'A'
1178eb385b40Sdan              WHEN var('b') THEN 'B'
1179eb385b40Sdan              WHEN var('c') THEN 'C'
1180eb385b40Sdan              ELSE 'no result'
1181eb385b40Sdan  END
1182eb385b40Sdan} {B}
1183eb385b40Sdanforeach {a b c} {0 1 1} break
1184eb385b40Sdando_execsql_test e_expr-21.2.2 {
1185eb385b40Sdan  SELECT CASE WHEN var('a') THEN 'A'
1186eb385b40Sdan              WHEN var('b') THEN 'B'
1187eb385b40Sdan              WHEN var('c') THEN 'C'
1188eb385b40Sdan              ELSE 'no result'
1189eb385b40Sdan  END
1190eb385b40Sdan} {B}
1191eb385b40Sdanforeach {a b c} {0 0 1} break
1192eb385b40Sdando_execsql_test e_expr-21.2.3 {
1193eb385b40Sdan  SELECT CASE WHEN var('a') THEN 'A'
1194eb385b40Sdan              WHEN var('b') THEN 'B'
1195eb385b40Sdan              WHEN var('c') THEN 'C'
1196eb385b40Sdan              ELSE 'no result'
1197eb385b40Sdan  END
1198eb385b40Sdan} {C}
1199eb385b40Sdan
1200eb385b40Sdan# EVIDENCE-OF: R-24227-04807 Or, if none of the WHEN expressions
1201eb385b40Sdan# evaluate to true, the result of evaluating the ELSE expression, if
1202eb385b40Sdan# any.
1203eb385b40Sdan#
1204eb385b40Sdanforeach {a b c} {0 0 0} break
1205eb385b40Sdando_execsql_test e_expr-21.3.1 {
1206eb385b40Sdan  SELECT CASE WHEN var('a') THEN 'A'
1207eb385b40Sdan              WHEN var('b') THEN 'B'
1208eb385b40Sdan              WHEN var('c') THEN 'C'
1209eb385b40Sdan              ELSE 'no result'
1210eb385b40Sdan  END
1211eb385b40Sdan} {{no result}}
1212eb385b40Sdan
1213eb385b40Sdan# EVIDENCE-OF: R-14168-07579 If there is no ELSE expression and none of
1214eb385b40Sdan# the WHEN expressions are true, then the overall result is NULL.
1215eb385b40Sdan#
1216eb385b40Sdandb nullvalue null
1217eb385b40Sdando_execsql_test e_expr-21.3.2 {
1218eb385b40Sdan  SELECT CASE WHEN var('a') THEN 'A'
1219eb385b40Sdan              WHEN var('b') THEN 'B'
1220eb385b40Sdan              WHEN var('c') THEN 'C'
1221eb385b40Sdan  END
1222eb385b40Sdan} {null}
1223eb385b40Sdandb nullvalue {}
1224eb385b40Sdan
1225eb385b40Sdan# EVIDENCE-OF: R-13943-13592 A NULL result is considered untrue when
1226eb385b40Sdan# evaluating WHEN terms.
1227eb385b40Sdan#
1228eb385b40Sdando_execsql_test e_expr-21.4.1 {
1229eb385b40Sdan  SELECT CASE WHEN NULL THEN 'A' WHEN 1 THEN 'B' END
1230eb385b40Sdan} {B}
1231eb385b40Sdando_execsql_test e_expr-21.4.2 {
1232eb385b40Sdan  SELECT CASE WHEN 0 THEN 'A' WHEN NULL THEN 'B' ELSE 'C' END
1233eb385b40Sdan} {C}
1234eb385b40Sdan
1235eb385b40Sdan# EVIDENCE-OF: R-38620-19499 In a CASE with a base expression, the base
1236eb385b40Sdan# expression is evaluated just once and the result is compared against
1237eb385b40Sdan# the evaluation of each WHEN expression from left to right.
1238eb385b40Sdan#
1239eb385b40Sdan# Note: This test case tests the "evaluated just once" part of the above
1240eb385b40Sdan# statement. Tests associated with the next two statements test that the
1241eb385b40Sdan# comparisons take place.
1242eb385b40Sdan#
1243eb385b40Sdanforeach {a b c} [list [expr 3] [expr 4] [expr 5]] break
1244eb385b40Sdanset ::varlist [list]
1245eb385b40Sdando_execsql_test e_expr-22.1.1 {
1246eb385b40Sdan  SELECT CASE var('a') WHEN 1 THEN 'A' WHEN 2 THEN 'B' WHEN 3 THEN 'C' END
1247eb385b40Sdan} {C}
1248eb385b40Sdando_test e_expr-22.1.2 { set ::varlist } {a}
1249eb385b40Sdan
1250eb385b40Sdan# EVIDENCE-OF: R-07667-49537 The result of the CASE expression is the
1251eb385b40Sdan# evaluation of the THEN expression that corresponds to the first WHEN
1252eb385b40Sdan# expression for which the comparison is true.
1253eb385b40Sdan#
1254eb385b40Sdando_execsql_test e_expr-22.2.1 {
1255eb385b40Sdan  SELECT CASE 23 WHEN 1 THEN 'A' WHEN 23 THEN 'B' WHEN 23 THEN 'C' END
1256eb385b40Sdan} {B}
1257eb385b40Sdando_execsql_test e_expr-22.2.2 {
1258eb385b40Sdan  SELECT CASE 1 WHEN 1 THEN 'A' WHEN 23 THEN 'B' WHEN 23 THEN 'C' END
1259eb385b40Sdan} {A}
1260eb385b40Sdan
1261eb385b40Sdan# EVIDENCE-OF: R-47543-32145 Or, if none of the WHEN expressions
1262eb385b40Sdan# evaluate to a value equal to the base expression, the result of
1263eb385b40Sdan# evaluating the ELSE expression, if any.
1264eb385b40Sdan#
1265eb385b40Sdando_execsql_test e_expr-22.3.1 {
1266eb385b40Sdan  SELECT CASE 24 WHEN 1 THEN 'A' WHEN 23 THEN 'B' WHEN 23 THEN 'C' ELSE 'D' END
1267eb385b40Sdan} {D}
1268eb385b40Sdan
1269eb385b40Sdan# EVIDENCE-OF: R-54721-48557 If there is no ELSE expression and none of
1270eb385b40Sdan# the WHEN expressions produce a result equal to the base expression,
1271eb385b40Sdan# the overall result is NULL.
1272eb385b40Sdan#
1273eb385b40Sdando_execsql_test e_expr-22.4.1 {
1274eb385b40Sdan  SELECT CASE 24 WHEN 1 THEN 'A' WHEN 23 THEN 'B' WHEN 23 THEN 'C' END
1275eb385b40Sdan} {{}}
1276eb385b40Sdandb nullvalue null
1277eb385b40Sdando_execsql_test e_expr-22.4.2 {
1278eb385b40Sdan  SELECT CASE 24 WHEN 1 THEN 'A' WHEN 23 THEN 'B' WHEN 23 THEN 'C' END
1279eb385b40Sdan} {null}
1280eb385b40Sdandb nullvalue {}
1281eb385b40Sdan
1282eb385b40Sdan# EVIDENCE-OF: R-11479-62774 When comparing a base expression against a
1283eb385b40Sdan# WHEN expression, the same collating sequence, affinity, and
1284eb385b40Sdan# NULL-handling rules apply as if the base expression and WHEN
1285eb385b40Sdan# expression are respectively the left- and right-hand operands of an =
1286eb385b40Sdan# operator.
1287eb385b40Sdan#
1288eb385b40Sdanproc rev {str} {
1289eb385b40Sdan  set ret ""
1290eb385b40Sdan  set chars [split $str]
1291eb385b40Sdan  for {set i [expr [llength $chars]-1]} {$i>=0} {incr i -1} {
1292eb385b40Sdan    append ret [lindex $chars $i]
1293eb385b40Sdan  }
1294eb385b40Sdan  set ret
1295eb385b40Sdan}
1296eb385b40Sdanproc reverse {lhs rhs} {
1297c0c3c262Sdan  string compare [rev $lhs] [rev $rhs]
1298eb385b40Sdan}
1299eb385b40Sdandb collate reverse reverse
1300eb385b40Sdando_execsql_test e_expr-23.1.1 {
1301eb385b40Sdan  CREATE TABLE t1(
1302eb385b40Sdan    a TEXT     COLLATE NOCASE,
1303eb385b40Sdan    b          COLLATE REVERSE,
1304eb385b40Sdan    c INTEGER,
1305eb385b40Sdan    d BLOB
1306eb385b40Sdan  );
1307eb385b40Sdan  INSERT INTO t1 VALUES('abc', 'cba', 55, 34.5);
1308eb385b40Sdan} {}
1309eb385b40Sdando_execsql_test e_expr-23.1.2 {
1310eb385b40Sdan  SELECT CASE a WHEN 'xyz' THEN 'A' WHEN 'AbC' THEN 'B' END FROM t1
1311eb385b40Sdan} {B}
1312eb385b40Sdando_execsql_test e_expr-23.1.3 {
1313eb385b40Sdan  SELECT CASE 'AbC' WHEN 'abc' THEN 'A' WHEN a THEN 'B' END FROM t1
1314eb385b40Sdan} {B}
1315eb385b40Sdando_execsql_test e_expr-23.1.4 {
1316eb385b40Sdan  SELECT CASE a WHEN b THEN 'A' ELSE 'B' END FROM t1
1317eb385b40Sdan} {B}
1318eb385b40Sdando_execsql_test e_expr-23.1.5 {
1319eb385b40Sdan  SELECT CASE b WHEN a THEN 'A' ELSE 'B' END FROM t1
1320c0c3c262Sdan} {B}
1321eb385b40Sdando_execsql_test e_expr-23.1.6 {
1322eb385b40Sdan  SELECT CASE 55 WHEN '55' THEN 'A' ELSE 'B' END
1323eb385b40Sdan} {B}
1324eb385b40Sdando_execsql_test e_expr-23.1.7 {
1325eb385b40Sdan  SELECT CASE c WHEN '55' THEN 'A' ELSE 'B' END FROM t1
1326eb385b40Sdan} {A}
1327eb385b40Sdando_execsql_test e_expr-23.1.8 {
1328eb385b40Sdan  SELECT CASE '34.5' WHEN d THEN 'A' ELSE 'B' END FROM t1
1329eb385b40Sdan} {B}
1330eb385b40Sdando_execsql_test e_expr-23.1.9 {
1331eb385b40Sdan  SELECT CASE NULL WHEN NULL THEN 'A' ELSE 'B' END
1332eb385b40Sdan} {B}
1333eb385b40Sdan
1334eb385b40Sdan# EVIDENCE-OF: R-37304-39405 If the base expression is NULL then the
1335eb385b40Sdan# result of the CASE is always the result of evaluating the ELSE
1336eb385b40Sdan# expression if it exists, or NULL if it does not.
1337eb385b40Sdan#
1338eb385b40Sdando_execsql_test e_expr-24.1.1 {
1339eb385b40Sdan  SELECT CASE NULL WHEN 'abc' THEN 'A' WHEN 'def' THEN 'B' END;
1340eb385b40Sdan} {{}}
1341eb385b40Sdando_execsql_test e_expr-24.1.2 {
1342eb385b40Sdan  SELECT CASE NULL WHEN 'abc' THEN 'A' WHEN 'def' THEN 'B' ELSE 'C' END;
1343eb385b40Sdan} {C}
1344eb385b40Sdan
1345eb385b40Sdan# EVIDENCE-OF: R-56280-17369 Both forms of the CASE expression use lazy,
1346eb385b40Sdan# or short-circuit, evaluation.
1347eb385b40Sdan#
1348eb385b40Sdanset varlist [list]
1349eb385b40Sdanforeach {a b c} {0 1 0} break
1350eb385b40Sdando_execsql_test e_expr-25.1.1 {
1351eb385b40Sdan  SELECT CASE WHEN var('a') THEN 'A'
1352eb385b40Sdan              WHEN var('b') THEN 'B'
1353eb385b40Sdan              WHEN var('c') THEN 'C'
1354eb385b40Sdan  END
1355eb385b40Sdan} {B}
1356eb385b40Sdando_test e_expr-25.1.2 { set ::varlist } {a b}
1357eb385b40Sdanset varlist [list]
1358eb385b40Sdando_execsql_test e_expr-25.1.3 {
1359eb385b40Sdan  SELECT CASE '0' WHEN var('a') THEN 'A'
1360eb385b40Sdan                  WHEN var('b') THEN 'B'
1361eb385b40Sdan                  WHEN var('c') THEN 'C'
1362eb385b40Sdan  END
1363eb385b40Sdan} {A}
1364eb385b40Sdando_test e_expr-25.1.4 { set ::varlist } {a}
1365eb385b40Sdan
1366eb385b40Sdan# EVIDENCE-OF: R-34773-62253 The only difference between the following
1367eb385b40Sdan# two CASE expressions is that the x expression is evaluated exactly
1368eb385b40Sdan# once in the first example but might be evaluated multiple times in the
1369eb385b40Sdan# second: CASE x WHEN w1 THEN r1 WHEN w2 THEN r2 ELSE r3 END CASE WHEN
1370eb385b40Sdan# x=w1 THEN r1 WHEN x=w2 THEN r2 ELSE r3 END
1371eb385b40Sdan#
1372eb385b40Sdanproc ceval {x} {
1373eb385b40Sdan  incr ::evalcount
1374eb385b40Sdan  return $x
1375eb385b40Sdan}
1376eb385b40Sdandb func ceval ceval
1377eb385b40Sdanset ::evalcount 0
1378eb385b40Sdan
1379eb385b40Sdando_execsql_test e_expr-26.1.1 {
1380eb385b40Sdan  CREATE TABLE t2(x, w1, r1, w2, r2, r3);
1381eb385b40Sdan  INSERT INTO t2 VALUES(1, 1, 'R1', 2, 'R2', 'R3');
1382eb385b40Sdan  INSERT INTO t2 VALUES(2, 1, 'R1', 2, 'R2', 'R3');
1383eb385b40Sdan  INSERT INTO t2 VALUES(3, 1, 'R1', 2, 'R2', 'R3');
1384eb385b40Sdan} {}
1385eb385b40Sdando_execsql_test e_expr-26.1.2 {
1386eb385b40Sdan  SELECT CASE x WHEN w1 THEN r1 WHEN w2 THEN r2 ELSE r3 END FROM t2
1387eb385b40Sdan} {R1 R2 R3}
1388eb385b40Sdando_execsql_test e_expr-26.1.3 {
1389eb385b40Sdan  SELECT CASE WHEN x=w1 THEN r1 WHEN x=w2 THEN r2 ELSE r3 END FROM t2
1390eb385b40Sdan} {R1 R2 R3}
1391eb385b40Sdan
1392eb385b40Sdando_execsql_test e_expr-26.1.4 {
1393eb385b40Sdan  SELECT CASE ceval(x) WHEN w1 THEN r1 WHEN w2 THEN r2 ELSE r3 END FROM t2
1394eb385b40Sdan} {R1 R2 R3}
1395eb385b40Sdando_test e_expr-26.1.5 { set ::evalcount } {3}
1396eb385b40Sdanset ::evalcount 0
1397eb385b40Sdando_execsql_test e_expr-26.1.6 {
1398eb385b40Sdan  SELECT CASE
1399eb385b40Sdan    WHEN ceval(x)=w1 THEN r1
1400eb385b40Sdan    WHEN ceval(x)=w2 THEN r2
1401eb385b40Sdan    ELSE r3 END
1402eb385b40Sdan  FROM t2
1403eb385b40Sdan} {R1 R2 R3}
1404eb385b40Sdando_test e_expr-26.1.6 { set ::evalcount } {5}
1405994e9403Sdan
140651f3a505Sdan
140751f3a505Sdan#-------------------------------------------------------------------------
140851f3a505Sdan# Test statements related to CAST expressions.
140951f3a505Sdan#
14109338642cSdrh# EVIDENCE-OF: R-20854-17109 A CAST conversion is similar to the
14119338642cSdrh# conversion that takes place when a column affinity is applied to a
14129338642cSdrh# value except that with the CAST operator the conversion always takes
14139338642cSdrh# place even if the conversion lossy and irreversible, whereas column
14149338642cSdrh# affinity only changes the data type of a value if the change is
14159338642cSdrh# lossless and reversible.
141651f3a505Sdan#
141751f3a505Sdando_execsql_test e_expr-27.1.1 {
141851f3a505Sdan  CREATE TABLE t3(a TEXT, b REAL, c INTEGER);
141951f3a505Sdan  INSERT INTO t3 VALUES(X'555655', '1.23abc', 4.5);
142051f3a505Sdan  SELECT typeof(a), a, typeof(b), b, typeof(c), c FROM t3;
142151f3a505Sdan} {blob UVU text 1.23abc real 4.5}
142251f3a505Sdando_execsql_test e_expr-27.1.2 {
142351f3a505Sdan  SELECT
142451f3a505Sdan    typeof(CAST(X'555655' as TEXT)), CAST(X'555655' as TEXT),
142551f3a505Sdan    typeof(CAST('1.23abc' as REAL)), CAST('1.23abc' as REAL),
142651f3a505Sdan    typeof(CAST(4.5 as INTEGER)), CAST(4.5 as INTEGER)
142751f3a505Sdan} {text UVU real 1.23 integer 4}
142851f3a505Sdan
142951f3a505Sdan# EVIDENCE-OF: R-27225-65050 If the value of <expr> is NULL, then
143051f3a505Sdan# the result of the CAST expression is also NULL.
143151f3a505Sdan#
143251f3a505Sdando_expr_test e_expr-27.2.1 { CAST(NULL AS integer) } null {}
143351f3a505Sdando_expr_test e_expr-27.2.2 { CAST(NULL AS text) }    null {}
143451f3a505Sdando_expr_test e_expr-27.2.3 { CAST(NULL AS blob) }    null {}
143551f3a505Sdando_expr_test e_expr-27.2.4 { CAST(NULL AS number) }  null {}
143651f3a505Sdan
143751f3a505Sdan# EVIDENCE-OF: R-31076-23575 Casting a value to a <type-name> with
143851f3a505Sdan# no affinity causes the value to be converted into a BLOB.
143951f3a505Sdan#
144051f3a505Sdando_expr_test e_expr-27.3.1 { CAST('abc' AS blob)       } blob abc
144151f3a505Sdando_expr_test e_expr-27.3.2 { CAST('def' AS shobblob_x) } blob def
144251f3a505Sdando_expr_test e_expr-27.3.3 { CAST('ghi' AS abbLOb10)   } blob ghi
144351f3a505Sdan
144451f3a505Sdan# EVIDENCE-OF: R-22956-37754 Casting to a BLOB consists of first casting
144551f3a505Sdan# the value to TEXT in the encoding of the database connection, then
144651f3a505Sdan# interpreting the resulting byte sequence as a BLOB instead of as TEXT.
144751f3a505Sdan#
144851f3a505Sdando_qexpr_test e_expr-27.4.1 { CAST('ghi' AS blob) } X'676869'
144951f3a505Sdando_qexpr_test e_expr-27.4.2 { CAST(456 AS blob) }   X'343536'
145051f3a505Sdando_qexpr_test e_expr-27.4.3 { CAST(1.78 AS blob) }  X'312E3738'
145151f3a505Sdanrename db db2
145251f3a505Sdansqlite3 db :memory:
14536faa5fdfSshanehifcapable {utf16} {
145451f3a505Sdandb eval { PRAGMA encoding = 'utf-16le' }
145551f3a505Sdando_qexpr_test e_expr-27.4.4 { CAST('ghi' AS blob) } X'670068006900'
145651f3a505Sdando_qexpr_test e_expr-27.4.5 { CAST(456 AS blob) }   X'340035003600'
145751f3a505Sdando_qexpr_test e_expr-27.4.6 { CAST(1.78 AS blob) }  X'31002E0037003800'
14586faa5fdfSshaneh}
145951f3a505Sdandb close
146051f3a505Sdansqlite3 db :memory:
146151f3a505Sdandb eval { PRAGMA encoding = 'utf-16be' }
14626faa5fdfSshanehifcapable {utf16} {
146351f3a505Sdando_qexpr_test e_expr-27.4.7 { CAST('ghi' AS blob) } X'006700680069'
146451f3a505Sdando_qexpr_test e_expr-27.4.8 { CAST(456 AS blob) }   X'003400350036'
146551f3a505Sdando_qexpr_test e_expr-27.4.9 { CAST(1.78 AS blob) }  X'0031002E00370038'
14666faa5fdfSshaneh}
146751f3a505Sdandb close
146851f3a505Sdanrename db2 db
146951f3a505Sdan
147051f3a505Sdan# EVIDENCE-OF: R-04207-37981 To cast a BLOB value to TEXT, the sequence
147151f3a505Sdan# of bytes that make up the BLOB is interpreted as text encoded using
147251f3a505Sdan# the database encoding.
147351f3a505Sdan#
147451f3a505Sdando_expr_test e_expr-28.1.1 { CAST (X'676869' AS text) } text ghi
147551f3a505Sdando_expr_test e_expr-28.1.2 { CAST (X'670068006900' AS text) } text g
147651f3a505Sdanrename db db2
147751f3a505Sdansqlite3 db :memory:
147851f3a505Sdandb eval { PRAGMA encoding = 'utf-16le' }
14796faa5fdfSshanehifcapable {utf16} {
148051f3a505Sdando_expr_test e_expr-28.1.3 { CAST (X'676869' AS text) == 'ghi' } integer 0
148151f3a505Sdando_expr_test e_expr-28.1.4 { CAST (X'670068006900' AS text) } text ghi
14826faa5fdfSshaneh}
148351f3a505Sdandb close
148451f3a505Sdanrename db2 db
148551f3a505Sdan
148651f3a505Sdan# EVIDENCE-OF: R-22235-47006 Casting an INTEGER or REAL value into TEXT
148751f3a505Sdan# renders the value as if via sqlite3_snprintf() except that the
148851f3a505Sdan# resulting TEXT uses the encoding of the database connection.
148951f3a505Sdan#
149051f3a505Sdando_expr_test e_expr-28.2.1 { CAST (1 AS text)   }     text 1
149151f3a505Sdando_expr_test e_expr-28.2.2 { CAST (45 AS text)  }     text 45
149251f3a505Sdando_expr_test e_expr-28.2.3 { CAST (-45 AS text) }     text -45
149351f3a505Sdando_expr_test e_expr-28.2.4 { CAST (8.8 AS text)    }  text 8.8
149451f3a505Sdando_expr_test e_expr-28.2.5 { CAST (2.3e+5 AS text) }  text 230000.0
149551f3a505Sdando_expr_test e_expr-28.2.6 { CAST (-2.3e-5 AS text) } text -2.3e-05
149651f3a505Sdando_expr_test e_expr-28.2.7 { CAST (0.0 AS text) }     text 0.0
149751f3a505Sdando_expr_test e_expr-28.2.7 { CAST (0 AS text) }       text 0
149851f3a505Sdan
149951f3a505Sdan# EVIDENCE-OF: R-26346-36443 When casting a BLOB value to a REAL, the
150051f3a505Sdan# value is first converted to TEXT.
150151f3a505Sdan#
150251f3a505Sdando_expr_test e_expr-29.1.1 { CAST (X'312E3233' AS REAL) } real 1.23
150351f3a505Sdando_expr_test e_expr-29.1.2 { CAST (X'3233302E30' AS REAL) } real 230.0
150451f3a505Sdando_expr_test e_expr-29.1.3 { CAST (X'2D392E3837' AS REAL) } real -9.87
150551f3a505Sdando_expr_test e_expr-29.1.4 { CAST (X'302E30303031' AS REAL) } real 0.0001
150651f3a505Sdanrename db db2
150751f3a505Sdansqlite3 db :memory:
15086faa5fdfSshanehifcapable {utf16} {
150951f3a505Sdandb eval { PRAGMA encoding = 'utf-16le' }
151048d9e01eSdando_expr_test e_expr-29.1.5 {
151151f3a505Sdan    CAST (X'31002E0032003300' AS REAL) } real 1.23
151248d9e01eSdando_expr_test e_expr-29.1.6 {
151351f3a505Sdan    CAST (X'3200330030002E003000' AS REAL) } real 230.0
151448d9e01eSdando_expr_test e_expr-29.1.7 {
151551f3a505Sdan    CAST (X'2D0039002E0038003700' AS REAL) } real -9.87
151648d9e01eSdando_expr_test e_expr-29.1.8 {
151751f3a505Sdan    CAST (X'30002E003000300030003100' AS REAL) } real 0.0001
15186faa5fdfSshaneh}
151951f3a505Sdandb close
152051f3a505Sdanrename db2 db
152151f3a505Sdan
152248d9e01eSdan# EVIDENCE-OF: R-54898-34554 When casting a TEXT value to REAL, the
152348d9e01eSdan# longest possible prefix of the value that can be interpreted as a real
152448d9e01eSdan# number is extracted from the TEXT value and the remainder ignored.
152548d9e01eSdan#
152648d9e01eSdando_expr_test e_expr-29.2.1 { CAST('1.23abcd' AS REAL) } real 1.23
152748d9e01eSdando_expr_test e_expr-29.2.2 { CAST('1.45.23abcd' AS REAL) } real 1.45
152848d9e01eSdando_expr_test e_expr-29.2.3 { CAST('-2.12e-01ABC' AS REAL) } real -0.212
152948d9e01eSdando_expr_test e_expr-29.2.4 { CAST('1 2 3 4' AS REAL) } real 1.0
153051f3a505Sdan
153148d9e01eSdan# EVIDENCE-OF: R-11321-47427 Any leading spaces in the TEXT value are
153248d9e01eSdan# ignored when converging from TEXT to REAL.
153348d9e01eSdan#
153448d9e01eSdando_expr_test e_expr-29.3.1 { CAST(' 1.23abcd' AS REAL) } real 1.23
153548d9e01eSdando_expr_test e_expr-29.3.2 { CAST('    1.45.23abcd' AS REAL) } real 1.45
153648d9e01eSdando_expr_test e_expr-29.3.3 { CAST('   -2.12e-01ABC' AS REAL) } real -0.212
153748d9e01eSdando_expr_test e_expr-29.3.4 { CAST(' 1 2 3 4' AS REAL) } real 1.0
153848d9e01eSdan
153948d9e01eSdan# EVIDENCE-OF: R-22662-28218 If there is no prefix that can be
154048d9e01eSdan# interpreted as a real number, the result of the conversion is 0.0.
154148d9e01eSdan#
154248d9e01eSdando_expr_test e_expr-29.4.1 { CAST('' AS REAL) } real 0.0
154348d9e01eSdando_expr_test e_expr-29.4.2 { CAST('not a number' AS REAL) } real 0.0
154448d9e01eSdando_expr_test e_expr-29.4.3 { CAST('XXI' AS REAL) } real 0.0
154548d9e01eSdan
154648d9e01eSdan# EVIDENCE-OF: R-21829-14563 When casting a BLOB value to INTEGER, the
154748d9e01eSdan# value is first converted to TEXT.
154848d9e01eSdan#
154948d9e01eSdando_expr_test e_expr-30.1.1 { CAST(X'313233' AS INTEGER) } integer 123
155048d9e01eSdando_expr_test e_expr-30.1.2 { CAST(X'2D363738' AS INTEGER) } integer -678
155148d9e01eSdando_expr_test e_expr-30.1.3 {
155248d9e01eSdan  CAST(X'31303030303030' AS INTEGER)
155348d9e01eSdan} integer 1000000
155448d9e01eSdando_expr_test e_expr-30.1.4 {
155548d9e01eSdan  CAST(X'2D31313235383939393036383432363234' AS INTEGER)
155648d9e01eSdan} integer -1125899906842624
155748d9e01eSdan
155848d9e01eSdanrename db db2
155948d9e01eSdansqlite3 db :memory:
15606faa5fdfSshanehifcapable {utf16} {
156148d9e01eSdanexecsql { PRAGMA encoding = 'utf-16be' }
156248d9e01eSdando_expr_test e_expr-30.1.5 { CAST(X'003100320033' AS INTEGER) } integer 123
156348d9e01eSdando_expr_test e_expr-30.1.6 { CAST(X'002D003600370038' AS INTEGER) } integer -678
156448d9e01eSdando_expr_test e_expr-30.1.7 {
156548d9e01eSdan  CAST(X'0031003000300030003000300030' AS INTEGER)
156648d9e01eSdan} integer 1000000
156748d9e01eSdando_expr_test e_expr-30.1.8 {
156848d9e01eSdan  CAST(X'002D0031003100320035003800390039003900300036003800340032003600320034' AS INTEGER)
156948d9e01eSdan} integer -1125899906842624
15706faa5fdfSshaneh}
157148d9e01eSdandb close
157248d9e01eSdanrename db2 db
157348d9e01eSdan
157448d9e01eSdan# EVIDENCE-OF: R-47612-45842 When casting a TEXT value to INTEGER, the
157548d9e01eSdan# longest possible prefix of the value that can be interpreted as an
157648d9e01eSdan# integer number is extracted from the TEXT value and the remainder
157748d9e01eSdan# ignored.
157848d9e01eSdan#
157948d9e01eSdando_expr_test e_expr-30.2.1 { CAST('123abcd' AS INT) } integer 123
158048d9e01eSdando_expr_test e_expr-30.2.2 { CAST('14523abcd' AS INT) } integer 14523
158148d9e01eSdando_expr_test e_expr-30.2.3 { CAST('-2.12e-01ABC' AS INT) } integer -2
158248d9e01eSdando_expr_test e_expr-30.2.4 { CAST('1 2 3 4' AS INT) } integer 1
158348d9e01eSdan
158448d9e01eSdan# EVIDENCE-OF: R-34400-33772 Any leading spaces in the TEXT value when
158548d9e01eSdan# converting from TEXT to INTEGER are ignored.
158648d9e01eSdan#
158748d9e01eSdando_expr_test e_expr-30.3.1 { CAST('   123abcd' AS INT) } integer 123
158848d9e01eSdando_expr_test e_expr-30.3.2 { CAST('  14523abcd' AS INT) } integer 14523
158948d9e01eSdando_expr_test e_expr-30.3.3 { CAST(' -2.12e-01ABC' AS INT) } integer -2
159048d9e01eSdando_expr_test e_expr-30.3.4 { CAST('     1 2 3 4' AS INT) } integer 1
159148d9e01eSdan
159248d9e01eSdan# EVIDENCE-OF: R-43164-44276 If there is no prefix that can be
159348d9e01eSdan# interpreted as an integer number, the result of the conversion is 0.
159448d9e01eSdan#
159548d9e01eSdando_expr_test e_expr-30.4.1 { CAST('' AS INTEGER) } integer 0
159648d9e01eSdando_expr_test e_expr-30.4.2 { CAST('not a number' AS INTEGER) } integer 0
159748d9e01eSdando_expr_test e_expr-30.4.3 { CAST('XXI' AS INTEGER) } integer 0
159848d9e01eSdan
15999338642cSdrh# EVIDENCE-OF: R-02752-50091 A cast of a REAL value into an INTEGER
16009338642cSdrh# results in the integer between the REAL value and zero that is closest
16019338642cSdrh# to the REAL value.
160248d9e01eSdan#
160348d9e01eSdando_expr_test e_expr-31.1.1 { CAST(3.14159 AS INTEGER) } integer 3
160448d9e01eSdando_expr_test e_expr-31.1.2 { CAST(1.99999 AS INTEGER) } integer 1
160548d9e01eSdando_expr_test e_expr-31.1.3 { CAST(-1.99999 AS INTEGER) } integer -1
160648d9e01eSdando_expr_test e_expr-31.1.4 { CAST(-0.99999 AS INTEGER) } integer 0
160748d9e01eSdan
16081bcbc6a6Sdrh# EVIDENCE-OF: R-51517-40824 If a REAL is greater than the greatest
16091bcbc6a6Sdrh# possible signed integer (+9223372036854775807) then the result is the
16101bcbc6a6Sdrh# greatest possible signed integer and if the REAL is less than the
16111bcbc6a6Sdrh# least possible signed integer (-9223372036854775808) then the result
16121bcbc6a6Sdrh# is the least possible signed integer.
161348d9e01eSdan#
1614de1a8b8cSdrhdo_expr_test e_expr-31.2.1 { CAST(2e+50 AS INT) } integer 9223372036854775807
161548d9e01eSdando_expr_test e_expr-31.2.2 { CAST(-2e+50 AS INT) } integer -9223372036854775808
161648d9e01eSdando_expr_test e_expr-31.2.3 {
161748d9e01eSdan  CAST(-9223372036854775809.0 AS INT)
161848d9e01eSdan} integer -9223372036854775808
161948d9e01eSdando_expr_test e_expr-31.2.4 {
162048d9e01eSdan  CAST(9223372036854775809.0 AS INT)
1621de1a8b8cSdrh} integer 9223372036854775807
162248d9e01eSdan
162348d9e01eSdan
162448d9e01eSdan# EVIDENCE-OF: R-09295-61337 Casting a TEXT or BLOB value into NUMERIC
162548d9e01eSdan# first does a forced conversion into REAL but then further converts the
162648d9e01eSdan# result into INTEGER if and only if the conversion from REAL to INTEGER
162748d9e01eSdan# is lossless and reversible.
162848d9e01eSdan#
162948d9e01eSdando_expr_test e_expr-32.1.1 { CAST('45'   AS NUMERIC)  } integer 45
163048d9e01eSdando_expr_test e_expr-32.1.2 { CAST('45.0' AS NUMERIC)  } integer 45
163148d9e01eSdando_expr_test e_expr-32.1.3 { CAST('45.2' AS NUMERIC)  } real 45.2
163248d9e01eSdando_expr_test e_expr-32.1.4 { CAST('11abc' AS NUMERIC) } integer 11
163348d9e01eSdando_expr_test e_expr-32.1.5 { CAST('11.1abc' AS NUMERIC) } real 11.1
163448d9e01eSdan
163548d9e01eSdan# EVIDENCE-OF: R-30347-18702 Casting a REAL or INTEGER value to NUMERIC
163648d9e01eSdan# is a no-op, even if a real value could be losslessly converted to an
163748d9e01eSdan# integer.
163848d9e01eSdan#
163948d9e01eSdando_expr_test e_expr-32.2.1 { CAST(13.0 AS NUMERIC) } real 13.0
164048d9e01eSdando_expr_test e_expr-32.2.2 { CAST(13.5 AS NUMERIC) } real 13.5
164148d9e01eSdan
164248d9e01eSdando_expr_test e_expr-32.2.3 {
164348d9e01eSdan  CAST(-9223372036854775808 AS NUMERIC)
164448d9e01eSdan} integer -9223372036854775808
164548d9e01eSdando_expr_test e_expr-32.2.4 {
164648d9e01eSdan  CAST(9223372036854775807 AS NUMERIC)
164748d9e01eSdan} integer 9223372036854775807
164848d9e01eSdan
164948d9e01eSdan# EVIDENCE-OF: R-64550-29191 Note that the result from casting any
165048d9e01eSdan# non-BLOB value into a BLOB and the result from casting any BLOB value
165148d9e01eSdan# into a non-BLOB value may be different depending on whether the
165248d9e01eSdan# database encoding is UTF-8, UTF-16be, or UTF-16le.
165348d9e01eSdan#
16546faa5fdfSshanehifcapable {utf16} {
165548d9e01eSdansqlite3 db1 :memory: ; db1 eval { PRAGMA encoding = 'utf-8' }
165648d9e01eSdansqlite3 db2 :memory: ; db2 eval { PRAGMA encoding = 'utf-16le' }
165748d9e01eSdansqlite3 db3 :memory: ; db3 eval { PRAGMA encoding = 'utf-16be' }
165848d9e01eSdanforeach {tn castexpr differs} {
165948d9e01eSdan  1 { CAST(123 AS BLOB)    } 1
166048d9e01eSdan  2 { CAST('' AS BLOB)     } 0
166148d9e01eSdan  3 { CAST('abcd' AS BLOB) } 1
166248d9e01eSdan
166348d9e01eSdan  4 { CAST(X'abcd' AS TEXT) } 1
166448d9e01eSdan  5 { CAST(X'' AS TEXT)     } 0
166548d9e01eSdan} {
166648d9e01eSdan  set r1 [db1 eval "SELECT typeof($castexpr), quote($castexpr)"]
166748d9e01eSdan  set r2 [db2 eval "SELECT typeof($castexpr), quote($castexpr)"]
166848d9e01eSdan  set r3 [db3 eval "SELECT typeof($castexpr), quote($castexpr)"]
166948d9e01eSdan
167048d9e01eSdan  if {$differs} {
167148d9e01eSdan    set res [expr {$r1!=$r2 && $r2!=$r3}]
167248d9e01eSdan  } else {
167348d9e01eSdan    set res [expr {$r1==$r2 && $r2==$r3}]
167448d9e01eSdan  }
167548d9e01eSdan
167648d9e01eSdan  do_test e_expr-33.1.$tn {set res} 1
167748d9e01eSdan}
167848d9e01eSdandb1 close
167948d9e01eSdandb2 close
168048d9e01eSdandb3 close
16816faa5fdfSshaneh}
168248d9e01eSdan
16834336cc45Sdan#-------------------------------------------------------------------------
16844336cc45Sdan# Test statements related to the EXISTS and NOT EXISTS operators.
16854336cc45Sdan#
16864336cc45Sdancatch { db close }
1687fda06befSmistachkinforcedelete test.db
16884336cc45Sdansqlite3 db test.db
16894336cc45Sdan
16904336cc45Sdando_execsql_test e_expr-34.1 {
16914336cc45Sdan  CREATE TABLE t1(a, b);
16924336cc45Sdan  INSERT INTO t1 VALUES(1, 2);
16934336cc45Sdan  INSERT INTO t1 VALUES(NULL, 2);
16944336cc45Sdan  INSERT INTO t1 VALUES(1, NULL);
16954336cc45Sdan  INSERT INTO t1 VALUES(NULL, NULL);
16964336cc45Sdan} {}
16974336cc45Sdan
16984336cc45Sdan# EVIDENCE-OF: R-25588-27181 The EXISTS operator always evaluates to one
16994336cc45Sdan# of the integer values 0 and 1.
17004336cc45Sdan#
17014336cc45Sdan# This statement is not tested by itself. Instead, all e_expr-34.* tests
17024336cc45Sdan# following this point explicitly test that specific invocations of EXISTS
17034336cc45Sdan# return either integer 0 or integer 1.
17044336cc45Sdan#
17054336cc45Sdan
17064336cc45Sdan# EVIDENCE-OF: R-58553-63740 If executing the SELECT statement specified
17074336cc45Sdan# as the right-hand operand of the EXISTS operator would return one or
17084336cc45Sdan# more rows, then the EXISTS operator evaluates to 1.
17094336cc45Sdan#
17104336cc45Sdanforeach {tn expr} {
17114336cc45Sdan    1 { EXISTS ( SELECT a FROM t1 ) }
17124336cc45Sdan    2 { EXISTS ( SELECT b FROM t1 ) }
17134336cc45Sdan    3 { EXISTS ( SELECT 24 ) }
17144336cc45Sdan    4 { EXISTS ( SELECT NULL ) }
17154336cc45Sdan    5 { EXISTS ( SELECT a FROM t1 WHERE a IS NULL ) }
17164336cc45Sdan} {
17174336cc45Sdan  do_expr_test e_expr-34.2.$tn $expr integer 1
17184336cc45Sdan}
17194336cc45Sdan
17204336cc45Sdan# EVIDENCE-OF: R-19673-40972 If executing the SELECT would return no
17214336cc45Sdan# rows at all, then the EXISTS operator evaluates to 0.
17224336cc45Sdan#
17234336cc45Sdanforeach {tn expr} {
17244336cc45Sdan    1 { EXISTS ( SELECT a FROM t1 WHERE 0) }
17254336cc45Sdan    2 { EXISTS ( SELECT b FROM t1 WHERE a = 5) }
17264336cc45Sdan    3 { EXISTS ( SELECT 24 WHERE 0) }
17274336cc45Sdan    4 { EXISTS ( SELECT NULL WHERE 1=2) }
17284336cc45Sdan} {
17294336cc45Sdan  do_expr_test e_expr-34.3.$tn $expr integer 0
17304336cc45Sdan}
17314336cc45Sdan
17324336cc45Sdan# EVIDENCE-OF: R-35109-49139 The number of columns in each row returned
17334336cc45Sdan# by the SELECT statement (if any) and the specific values returned have
17344336cc45Sdan# no effect on the results of the EXISTS operator.
17354336cc45Sdan#
17364336cc45Sdanforeach {tn expr res} {
17374336cc45Sdan    1 { EXISTS ( SELECT * FROM t1 ) }                          1
17384336cc45Sdan    2 { EXISTS ( SELECT *, *, * FROM t1 ) }                    1
17394336cc45Sdan    3 { EXISTS ( SELECT 24, 25 ) }                             1
17404336cc45Sdan    4 { EXISTS ( SELECT NULL, NULL, NULL ) }                   1
17414336cc45Sdan    5 { EXISTS ( SELECT a,b,a||b FROM t1 WHERE a IS NULL ) }   1
17424336cc45Sdan
17434336cc45Sdan    6 { EXISTS ( SELECT a, a FROM t1 WHERE 0) }                0
17444336cc45Sdan    7 { EXISTS ( SELECT b, b, a FROM t1 WHERE a = 5) }         0
17454336cc45Sdan    8 { EXISTS ( SELECT 24, 46, 89 WHERE 0) }                  0
17464336cc45Sdan    9 { EXISTS ( SELECT NULL, NULL WHERE 1=2) }                0
17474336cc45Sdan} {
17484336cc45Sdan  do_expr_test e_expr-34.4.$tn $expr integer $res
17494336cc45Sdan}
17504336cc45Sdan
17514336cc45Sdan# EVIDENCE-OF: R-10645-12439 In particular, rows containing NULL values
17524336cc45Sdan# are not handled any differently from rows without NULL values.
17534336cc45Sdan#
17544336cc45Sdanforeach {tn e1 e2} {
17554336cc45Sdan  1 { EXISTS (SELECT 'not null') }    { EXISTS (SELECT NULL) }
17564336cc45Sdan  2 { EXISTS (SELECT NULL FROM t1) }  { EXISTS (SELECT 'bread' FROM t1) }
17574336cc45Sdan} {
17584336cc45Sdan  set res [db one "SELECT $e1"]
17594336cc45Sdan  do_expr_test e_expr-34.5.${tn}a $e1 integer $res
17604336cc45Sdan  do_expr_test e_expr-34.5.${tn}b $e2 integer $res
17614336cc45Sdan}
17624336cc45Sdan
17634336cc45Sdan#-------------------------------------------------------------------------
176474b617b2Sdan# Test statements related to scalar sub-queries.
17654336cc45Sdan#
17664336cc45Sdan
176774b617b2Sdancatch { db close }
1768fda06befSmistachkinforcedelete test.db
176974b617b2Sdansqlite3 db test.db
177074b617b2Sdando_test e_expr-35.0 {
177174b617b2Sdan  execsql {
177274b617b2Sdan    CREATE TABLE t2(a, b);
177374b617b2Sdan    INSERT INTO t2 VALUES('one', 'two');
177474b617b2Sdan    INSERT INTO t2 VALUES('three', NULL);
177574b617b2Sdan    INSERT INTO t2 VALUES(4, 5.0);
177674b617b2Sdan  }
177774b617b2Sdan} {}
177874b617b2Sdan
177974b617b2Sdan# EVIDENCE-OF: R-00980-39256 A SELECT statement enclosed in parentheses
178074b617b2Sdan# may appear as a scalar quantity.
178174b617b2Sdan#
178274b617b2Sdan# EVIDENCE-OF: R-56294-03966 All types of SELECT statement, including
178374b617b2Sdan# aggregate and compound SELECT queries (queries with keywords like
178474b617b2Sdan# UNION or EXCEPT) are allowed as scalar subqueries.
178574b617b2Sdan#
178674b617b2Sdando_expr_test e_expr-35.1.1 { (SELECT 35)   } integer 35
178774b617b2Sdando_expr_test e_expr-35.1.2 { (SELECT NULL) } null {}
178874b617b2Sdan
178974b617b2Sdando_expr_test e_expr-35.1.3 { (SELECT count(*) FROM t2) } integer 3
179074b617b2Sdando_expr_test e_expr-35.1.4 { (SELECT 4 FROM t2) } integer 4
179174b617b2Sdan
179274b617b2Sdando_expr_test e_expr-35.1.5 {
179374b617b2Sdan  (SELECT b FROM t2 UNION SELECT a+1 FROM t2)
179474b617b2Sdan} null {}
179574b617b2Sdando_expr_test e_expr-35.1.6 {
179674b617b2Sdan  (SELECT a FROM t2 UNION SELECT COALESCE(b, 55) FROM t2 ORDER BY 1)
179774b617b2Sdan} integer 4
179874b617b2Sdan
179974b617b2Sdan# EVIDENCE-OF: R-46899-53765 A SELECT used as a scalar quantity must
180074b617b2Sdan# return a result set with a single column.
180174b617b2Sdan#
180206ce4136Sdan# The following block tests that errors are returned in a bunch of cases
180306ce4136Sdan# where a subquery returns more than one column.
180406ce4136Sdan#
180574b617b2Sdanset M {only a single result allowed for a SELECT that is part of an expression}
180674b617b2Sdanforeach {tn sql} {
180774b617b2Sdan  1     { SELECT (SELECT * FROM t2 UNION SELECT a+1, b+1 FROM t2) }
180874b617b2Sdan  2     { SELECT (SELECT * FROM t2 UNION SELECT a+1, b+1 FROM t2 ORDER BY 1) }
180974b617b2Sdan  3     { SELECT (SELECT 1, 2) }
181074b617b2Sdan  4     { SELECT (SELECT NULL, NULL, NULL) }
181174b617b2Sdan  5     { SELECT (SELECT * FROM t2) }
181274b617b2Sdan  6     { SELECT (SELECT * FROM (SELECT 1, 2, 3)) }
181374b617b2Sdan} {
181474b617b2Sdan  do_catchsql_test e_expr-35.2.$tn $sql [list 1 $M]
181574b617b2Sdan}
181674b617b2Sdan
181706ce4136Sdan# EVIDENCE-OF: R-35764-28041 The result of the expression is the value
181806ce4136Sdan# of the only column in the first row returned by the SELECT statement.
181906ce4136Sdan#
182006ce4136Sdan# EVIDENCE-OF: R-41898-06686 If the SELECT yields more than one result
182106ce4136Sdan# row, all rows after the first are ignored.
182206ce4136Sdan#
182306ce4136Sdando_execsql_test e_expr-36.3.1 {
182406ce4136Sdan  CREATE TABLE t4(x, y);
182506ce4136Sdan  INSERT INTO t4 VALUES(1, 'one');
182606ce4136Sdan  INSERT INTO t4 VALUES(2, 'two');
182706ce4136Sdan  INSERT INTO t4 VALUES(3, 'three');
182806ce4136Sdan} {}
182906ce4136Sdan
183006ce4136Sdanforeach {tn expr restype resval} {
183106ce4136Sdan    2  { ( SELECT x FROM t4 ORDER BY x )      }        integer 1
183206ce4136Sdan    3  { ( SELECT x FROM t4 ORDER BY y )      }        integer 1
183306ce4136Sdan    4  { ( SELECT x FROM t4 ORDER BY x DESC ) }        integer 3
183406ce4136Sdan    5  { ( SELECT x FROM t4 ORDER BY y DESC ) }        integer 2
183506ce4136Sdan    6  { ( SELECT y FROM t4 ORDER BY y DESC ) }        text    two
183606ce4136Sdan
183706ce4136Sdan    7  { ( SELECT sum(x) FROM t4 )           }         integer 6
183806ce4136Sdan    8  { ( SELECT group_concat(y,'') FROM t4 ) }       text    onetwothree
183906ce4136Sdan    9  { ( SELECT max(x) FROM t4 WHERE y LIKE '___') } integer 2
184006ce4136Sdan
184106ce4136Sdan} {
184206ce4136Sdan  do_expr_test e_expr-36.3.$tn $expr $restype $resval
184306ce4136Sdan}
184406ce4136Sdan
184506ce4136Sdan# EVIDENCE-OF: R-25492-41572 If the SELECT yields no rows, then the
184606ce4136Sdan# value of the expression is NULL.
184706ce4136Sdan#
184806ce4136Sdanforeach {tn expr} {
184906ce4136Sdan    1  { ( SELECT x FROM t4 WHERE x>3 ORDER BY x )      }
185006ce4136Sdan    2  { ( SELECT x FROM t4 WHERE y<'one' ORDER BY y )  }
185106ce4136Sdan} {
185206ce4136Sdan  do_expr_test e_expr-36.4.$tn $expr null {}
185306ce4136Sdan}
185406ce4136Sdan
18552c7e9bfcSdrh# EVIDENCE-OF: R-62477-06476 For example, the values NULL, 0.0, 0,
18562c7e9bfcSdrh# 'english' and '0' are all considered to be false.
18572c7e9bfcSdrh#
18582c7e9bfcSdrhdo_execsql_test e_expr-37.1 {
18592c7e9bfcSdrh   SELECT CASE WHEN NULL THEN 'true' ELSE 'false' END;
18602c7e9bfcSdrh} {false}
18612c7e9bfcSdrhdo_execsql_test e_expr-37.2 {
18622c7e9bfcSdrh   SELECT CASE WHEN 0.0 THEN 'true' ELSE 'false' END;
18632c7e9bfcSdrh} {false}
18642c7e9bfcSdrhdo_execsql_test e_expr-37.3 {
18652c7e9bfcSdrh   SELECT CASE WHEN 0 THEN 'true' ELSE 'false' END;
18662c7e9bfcSdrh} {false}
18672c7e9bfcSdrhdo_execsql_test e_expr-37.4 {
18682c7e9bfcSdrh   SELECT CASE WHEN 'engligh' THEN 'true' ELSE 'false' END;
18692c7e9bfcSdrh} {false}
18702c7e9bfcSdrhdo_execsql_test e_expr-37.5 {
18712c7e9bfcSdrh   SELECT CASE WHEN '0' THEN 'true' ELSE 'false' END;
18722c7e9bfcSdrh} {false}
18732c7e9bfcSdrh
18742c7e9bfcSdrh# EVIDENCE-OF: R-55532-10108 Values 1, 1.0, 0.1, -0.1 and '1english' are
18752c7e9bfcSdrh# considered to be true.
18762c7e9bfcSdrh#
18772c7e9bfcSdrhdo_execsql_test e_expr-37.6 {
18782c7e9bfcSdrh   SELECT CASE WHEN 1 THEN 'true' ELSE 'false' END;
18792c7e9bfcSdrh} {true}
18802c7e9bfcSdrhdo_execsql_test e_expr-37.7 {
18812c7e9bfcSdrh   SELECT CASE WHEN 1.0 THEN 'true' ELSE 'false' END;
18822c7e9bfcSdrh} {true}
18832c7e9bfcSdrhdo_execsql_test e_expr-37.8 {
18842c7e9bfcSdrh   SELECT CASE WHEN 0.1 THEN 'true' ELSE 'false' END;
18852c7e9bfcSdrh} {true}
18862c7e9bfcSdrhdo_execsql_test e_expr-37.9 {
18872c7e9bfcSdrh   SELECT CASE WHEN -0.1 THEN 'true' ELSE 'false' END;
18882c7e9bfcSdrh} {true}
18892c7e9bfcSdrhdo_execsql_test e_expr-37.10 {
18902c7e9bfcSdrh   SELECT CASE WHEN '1english' THEN 'true' ELSE 'false' END;
18912c7e9bfcSdrh} {true}
18922c7e9bfcSdrh
189306ce4136Sdan
189448d9e01eSdanfinish_test
1895