File: existsexpr.test

package info (click to toggle)
sqlcipher 4.13.0-1
  • links: PTS, VCS
  • area: main
  • in suites: forky, sid
  • size: 119,564 kB
  • sloc: ansic: 290,172; tcl: 24,955; javascript: 13,486; java: 8,153; sh: 7,784; makefile: 2,247; yacc: 1,727; cs: 307; sql: 73
file content (517 lines) | stat: -rw-r--r-- 11,181 bytes parent folder | download
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
# 2024 May 25
#
# The author disclaims copyright to this source code.  In place of
# a legal notice, here is a blessing:
#
#    May you do good and not evil.
#    May you find forgiveness for yourself and forgive others.
#    May you share freely, never taking more than you give.
#
#***********************************************************************
#

set testdir [file dirname $argv0]
source $testdir/tester.tcl
source $testdir/lock_common.tcl
set testprefix existsexpr

do_execsql_test 1.0 {
  CREATE TABLE x1(a, b, PRIMARY KEY(a)) WITHOUT ROWID;
  INSERT INTO x1 VALUES(1, 2), (3, 4), (5, 6);
  CREATE INDEX x1b ON x1(b);

  CREATE TABLE x2(x, y);
  INSERT INTO x2 VALUES(1, 2), (3, 4), (5, 6);
}

do_execsql_test 1.1 {
  SELECT 1 WHERE EXISTS (SELECT 1 FROM x1 WHERE a=5)
} {1}

do_execsql_test 1.2 {
  SELECT * FROM x2 WHERE EXISTS (SELECT 1 FROM x1 WHERE a=x)
} {1 2 3 4 5 6}

# With "a=x", the UNIQUE index means the EXIST can be transformed to a join.
# So no "SUBQUERY". With "b=x", the index is not UNIQUE and so there is a
# "SUBQUERY".
do_execsql_test 1.3.1 {
  EXPLAIN QUERY PLAN
  SELECT * FROM x2 WHERE EXISTS (SELECT 1 FROM x1 WHERE a=x)
} {~/SUBQUERY/}
do_execsql_test 1.3.2 {
  EXPLAIN QUERY PLAN
  SELECT * FROM x2 WHERE EXISTS (SELECT 1 FROM x1 WHERE b=x)
} {~/SUBQUERY/}

do_execsql_test 1.4.1 {
  EXPLAIN QUERY PLAN
  SELECT * FROM x2 WHERE x=1 AND EXISTS (SELECT 1 FROM x1 WHERE a=x)
} {~/SUBQUERY/}
do_execsql_test 1.4.2 {
  EXPLAIN QUERY PLAN
  SELECT * FROM x2 WHERE EXISTS (SELECT 1 FROM x1 WHERE a=x) AND y=2
} {~/SUBQUERY/}

do_execsql_test 1.5 {
  SELECT count(*) FROM x2 WHERE EXISTS (SELECT 1 FROM x1 WHERE a=x)
} {3}

#-------------------------------------------------------------------------
do_execsql_test 2.0 {
  CREATE TABLE t1(a, b);
  WITH s(i) AS (
    SELECT 1 UNION ALL SELECT i+1 FROM s WHERE i<1000
  ) INSERT INTO t1 SELECT i, i FROM s;

  CREATE TABLE t2(c, d);
  WITH s(i) AS (
    SELECT 10 UNION ALL SELECT i+10 FROM s WHERE i<1000
  ) INSERT INTO t2 SELECT i, i FROM s;
}

do_execsql_test 2.1 {
  SELECT count(*) FROM t1;
  SELECT count(*) FROM t2;
} {1000 100}

do_execsql_test 2.2 {
  SELECT count(*) FROM t1, t2 WHERE a=c;
} {100}

do_execsql_test 2.3 {
  SELECT count(*) FROM t1 WHERE EXISTS (SELECT 1 FROM t2 WHERE c=a)
} {100}
do_eqp_test 2.4 {
  SELECT count(*) FROM t1 WHERE EXISTS (SELECT 1 FROM t2 WHERE c=a)
} {SCAN t1}

do_execsql_test 2.4.0 {
  CREATE UNIQUE INDEX t2c ON t2(c);
  CREATE UNIQUE INDEX t1a ON t1(a);
}

do_eqp_test 2.4.1 {
  SELECT count(*) FROM t1 WHERE EXISTS (SELECT 1 FROM t2 WHERE c=a);
} {SCAN t1*t2 EXISTS}
do_execsql_test 2.4.2 {
  ANALYZE;
}
do_eqp_test 2.4.3 {
  SELECT count(*) FROM t1 WHERE EXISTS (SELECT 1 FROM t2 WHERE c=a);
} {SCAN t1*t2 EXISTS}
do_execsql_test 2.4.4 {
  SELECT count(*) FROM t1 WHERE EXISTS (SELECT 1 FROM t2 WHERE c=a);
} {100}

do_execsql_test 2.5.1 {
  EXPLAIN QUERY PLAN
  SELECT count(*) FROM t1 WHERE EXISTS (SELECT 1 FROM t2 WHERE t2.rowid=a);
} {~/SUBQUERY/}

#-------------------------------------------------------------------------
proc do_subquery_test {tn bSub sql res} {
  set r1(0) ~/SUBQUERY/
  set r1(1) /SUBQUERY/
  do_execsql_test $tn.1 "explain query plan $sql" $r1($bSub)
  do_execsql_test $tn.2 $sql $res
}

do_execsql_test 3.0 {
  CREATE TABLE y1(a, b, c);
  CREATE TABLE y2(x, y, z);
  CREATE UNIQUE INDEX y2zy ON y2(z, y);

  INSERT INTO y1 VALUES(1, 1, 1);
  INSERT INTO y1 VALUES(2, 2, 2);
  INSERT INTO y1 VALUES(3, 3, 3);
  INSERT INTO y1 VALUES(4, 4, 4);

  INSERT INTO y2 VALUES(1, 1, 1);
  INSERT INTO y2 VALUES(3, 3, 3);
}

do_subquery_test 3.1 0 {
  SELECT * FROM y1 WHERE EXISTS ( 
      SELECT 1 FROM y2 WHERE z=a AND y=b AND x=z
  )
} {
  1 1 1          3 3 3
}    

do_subquery_test 3.2 0 {
  SELECT * FROM y1 WHERE EXISTS ( 
      SELECT 1 FROM y2 WHERE z=max(a,b) AND y=min(b,a) AND x=z
  )
} {
  1 1 1          3 3 3
}    

do_subquery_test 3.3 0 {
  SELECT * FROM y1 WHERE EXISTS ( 
      SELECT 1 FROM y2 WHERE z=max(a,b) AND y=min(b,a) AND c!=3
  )
} {
  1 1 1
}    

do_subquery_test 3.4 0 {
  SELECT * FROM y1 WHERE EXISTS ( 
      SELECT 1 FROM y2 WHERE z=max(a,b) AND b=3
  )
} {
  3 3 3
}    

do_subquery_test 3.5 0 {
  SELECT * FROM y1 WHERE EXISTS ( 
      SELECT 1 FROM y2 WHERE z=a-1 AND y=a-1
  )
} {
  2 2 2
  4 4 4
}    

do_subquery_test 3.6 0 {
  SELECT * FROM y1 WHERE EXISTS ( 
      SELECT 1 FROM y2 WHERE z=a-1 AND y+1=a
  )
} {
  2 2 2
  4 4 4
}    

do_subquery_test 3.7 1 {
  SELECT * FROM y1 WHERE EXISTS ( 
      SELECT count(*) FROM y2 WHERE z=a-1 AND y=a-1
  )
} {
  1 1 1
  2 2 2
  3 3 3
  4 4 4
}    

do_subquery_test 3.8 0 {
  SELECT * FROM y1 WHERE EXISTS ( SELECT a+1 FROM y2 )
} {
  1 1 1
  2 2 2
  3 3 3
  4 4 4
}    

do_subquery_test 3.9 1 {
  SELECT * FROM y1 WHERE EXISTS ( 
      SELECT 1 FROM y2 one, y2 two WHERE one.z=a-1 AND one.y=a-1
  )
} {
  2 2 2
  4 4 4
}    

#-------------------------------------------------------------------------
reset_db
do_execsql_test 4.0 {
  CREATE TABLE tx1(a TEXT COLLATE nocase, b TEXT);
  CREATE UNIQUE INDEX tx1ab ON tx1(a, b);

  INSERT INTO tx1 VALUES('a', 'a');
  INSERT INTO tx1 VALUES('B', 'b');
  INSERT INTO tx1 VALUES('c', 'c');
  INSERT INTO tx1 VALUES('D', 'd');
  INSERT INTO tx1 VALUES('e', 'e');

  CREATE TABLE tx2(x, y);
  INSERT INTO tx2 VALUES('A', 'a');
  INSERT INTO tx2 VALUES('b', 'b');
  INSERT INTO tx2 VALUES('C', 'c');
  INSERT INTO tx2 VALUES('D', 'd');
}

do_subquery_test 4.1 0 {
  SELECT * FROM tx2 WHERE EXISTS (
    SELECT 1 FROM tx1 WHERE a=x AND b=y
  )
} {
  A a
  b b
  C c
  D d
}

do_subquery_test 4.1.1 0 {
  SELECT * FROM tx2 WHERE EXISTS (
    SELECT 1 FROM tx1 WHERE (a COLLATE nocase)=x AND b=y
  )
} {
  A a   b b   C c   D d
}
do_subquery_test 4.1.2 0 {
  SELECT * FROM tx2 WHERE EXISTS (
    SELECT 1 FROM tx1 WHERE a=x AND (b COLLATE binary)=y
  )
} {
  A a   b b   C c   D d
}
do_subquery_test 4.1.1 0 {
  SELECT * FROM tx2 WHERE EXISTS (
    SELECT 1 FROM tx1 WHERE x=(a COLLATE nocase) AND b=y
  )
} {
  A a   b b   C c   D d
}
do_subquery_test 4.1.2 0 {
  SELECT * FROM tx2 WHERE EXISTS (
    SELECT 1 FROM tx1 WHERE a=x AND y=(b COLLATE binary)
  )
} {
  A a   b b   C c   D d
}

do_subquery_test 4.2 0 {
  SELECT * FROM tx2 WHERE EXISTS (
    SELECT 1 FROM tx1 WHERE a=x AND b=y COLLATE nocase
  )
} {
  A a
  b b
  C c
  D d
}

do_execsql_test 4.3 {
  DROP INDEX tx1ab;
  CREATE UNIQUE INDEX tx1ab ON tx1(a COLLATE binary, b);
}

do_subquery_test 4.4 0 {
  SELECT * FROM tx2 WHERE EXISTS (
    SELECT 1 FROM tx1 WHERE a=x AND b=y
  )
} {
  A a
  b b
  C c
  D d
}

do_subquery_test 4.4 0 {
  SELECT * FROM tx2 WHERE EXISTS (
    SELECT 1 FROM tx1 WHERE a=x COLLATE binary AND b=y
  )
} {
  D d
}

do_subquery_test 4.4 1 {
  SELECT EXISTS ( SELECT x FROM tx1 ) FROM tx2
} {
  1 1 1 1
}

do_subquery_test 4.4 1 {
  SELECT (SELECT EXISTS ( SELECT x FROM tx1 ) WHERE 1) FROM tx2
} {
  1 1 1 1
}

#-------------------------------------------------------------------------
proc cols {s f} {
  set lCols [list]
  for {set i $s} {$i<=$f} {incr i} {
    lappend lCols [format "c%02d" $i]
  }
  join $lCols ", "
}
proc vals {n val} {
  set lVal [list]
  for {set i 0} {$i<$n} {incr i} {
    lappend lVal $val
  }
  join $lVal ", "
}
proc exprs {s f} {
  set lExpr [list]
  for {set i $s} {$i<=$f} {incr i} {
    lappend lExpr [format "c%02d = o" $i]
  }
  join $lExpr " AND "
}


do_execsql_test 5.0 "
  CREATE TABLE a1( [cols 0 99] );
"
do_execsql_test 5.1 "
  -- 63 column index
  CREATE UNIQUE INDEX a1idx1 ON a1( [cols 0 62] );
"
do_execsql_test 5.2 "
  -- 64 column index
  CREATE UNIQUE INDEX a1idx2 ON a1( [cols 10 73] );
"
do_execsql_test 5.2 "
  -- 65 column index
  CREATE UNIQUE INDEX a1idx3 ON a1( [cols 20 84] );
"

do_test 5.3 {
  foreach v {1 2 3 4 5 6} {
    execsql "INSERT INTO a1 VALUES( [vals 100 $v] )"
  }
} {}

do_execsql_test 5.4 {
  CREATE TABLE a2(o);
  INSERT INTO a2 VALUES(2), (5); 
}

do_subquery_test 5.5 0 "
  SELECT o FROM a2 WHERE EXISTS (
    SELECT 1 FROM a1 WHERE [exprs 0 62]
  )
" {
  2 5
}

do_subquery_test 5.6 0 "
  SELECT o FROM a2 WHERE EXISTS (
    SELECT 1 FROM a1 WHERE [exprs 10 73]
  )
" {
  2 5
}

do_subquery_test 5.7 0 "
  SELECT o FROM a2 WHERE EXISTS (
    SELECT 1 FROM a1 WHERE [exprs 20 84]
  )
" {
  2 5
}

#-------------------------------------------------------------------------
reset_db
do_execsql_test 6.0 {
  CREATE TABLE t1(a, b UNIQUE, c UNIQUE);
  CREATE TABLE t2(a INfEGER PRIMARY KEY, b);
  CREATE UNIQUE INDEX t2b ON t2(b);
}

do_catchsql_test 6.1 {
  SELECT a FROM t1 WHERE EXISTS (SELECT 1 FROM t2 WHERE c COLLATE f = a)
} {1 {no such collation sequence: f}}

#-------------------------------------------------------------------------
reset_db
do_execsql_test 7.0 {
  CREATE TABLE t1(x);
  CREATE TABLE t2(y UNIQUE);

  INSERT INTO t1 VALUES(1), (2);
  INSERT INTO t2 VALUES(1), (3);

  SELECT * FROM t1 one LEFT JOIN t1 two ON (one.x=two.x AND EXISTS (
    SELECT 1 FROM t2 WHERE y=one.x
  ));
} {
  1 1
  2 {}
}

# https://sqlite.org/forum/forumpost/2025-07-23T10:59:14z
reset_db
do_execsql_test 8.0 {
  CREATE TABLE t0 (c0 INT);  INSERT INTO t0(c0) VALUES (1);
  CREATE TABLE t1(c0 INT);   INSERT INTO t1(c0) VALUES (2);
  SELECT * FROM t1 WHERE EXISTS (SELECT 1 FROM t0 LIMIT 0);
} {}

#-------------------------------------------------------------------------
reset_db

do_execsql_test 9.0 {
  CREATE TABLE t1(xx);
  INSERT INTO t1 VALUES('big string value');
} {}

do_execsql_test 9.1 {
  PRAGMA automatic_index = off;
  CREATE TABLE t2(ii);
  INSERT INTO t2 VALUES(100);
  INSERT INTO t2 VALUES(200);
}

do_execsql_test 9.2 {
  CREATE TABLE t3(yy);
  INSERT INTO t3 VALUES(200);
}

do_execsql_test 9.3 {
  SELECT 1 FROM t2 WHERE EXISTS ( SELECT 1 FROM t3 WHERE yy==t2.ii )
} {1}

do_execsql_test 9.4 {
  SELECT EXISTS (
    SELECT 1 FROM t2 WHERE EXISTS ( SELECT 1 FROM t3 WHERE yy==t2.ii )
  )
} {1}

do_execsql_test 9.5 {
  SELECT 1234 WHERE EXISTS (
    SELECT 1 FROM t2 WHERE EXISTS ( SELECT 1 FROM t3 WHERE yy==t2.ii )
  )
} {1234}

set Q {
  SELECT * FROM t1 WHERE 
    EXISTS (
      SELECT 1 FROM t2 WHERE EXISTS ( SELECT 1 FROM t3 WHERE yy==t2.ii ) 
    )
}

do_execsql_test 9.5 $Q {{big string value}}
catch { optimization_control db exists-to-join 0 }
db cache flush
do_execsql_test 9.6 $Q {{big string value}}

#-------------------------------------------------------------------------
reset_db

do_execsql_test 10.0 {
  CREATE TABLE t1(a);
  CREATE TABLE x1(x);
}

do_execsql_test 10.1 {
  SELECT EXISTS( SELECT 1 FROM t1 ) aaa FROM x1 WHERE aaa AND aaa
}

do_execsql_test 10.2 {
  SELECT 
    EXISTS( SELECT 1 FROM t1 ) aaa
  WHERE (
    SELECT 1 FROM x1 WHERE aaa AND aaa
  );
}

# https://sqlite.org/forum/forumpost/2026-01-03T14:05:48z
do_execsql_test 11.0 {
  CREATE TABLE parent (id TEXT PRIMARY KEY);
  CREATE TABLE child_a (id TEXT);
  CREATE TABLE child_b (id TEXT);
  INSERT INTO parent VALUES ('p1');
  INSERT INTO child_a VALUES ('p1');
}
do_execsql_test 11.1 {
  SELECT count(*), parent.id FROM parent
   WHERE EXISTS (
      SELECT 1 FROM child_a WHERE child_a.id = parent.id
      UNION
      SELECT 1 FROM child_b WHERE child_b.id = parent.id
   )
   GROUP BY id;
} {1 p1}

finish_test