xref: /sqlite-3.40.0/test/where3.test (revision dfe4e6bb)
1# 2006 January 31
2#
3# The author disclaims copyright to this source code.  In place of
4# a legal notice, here is a blessing:
5#
6#    May you do good and not evil.
7#    May you find forgiveness for yourself and forgive others.
8#    May you share freely, never taking more than you give.
9#
10#***********************************************************************
11# This file implements regression tests for SQLite library.  The
12# focus of this file is testing the join reordering optimization
13# in cases that include a LEFT JOIN.
14#
15# $Id: where3.test,v 1.4 2008/04/17 19:14:02 drh Exp $
16
17set testdir [file dirname $argv0]
18source $testdir/tester.tcl
19
20# The following is from ticket #1652.
21#
22# A comma join then a left outer join:  A,B left join C.
23# Arrange indices so that the B table is chosen to go first.
24# Also put an index on C, but make sure that A is chosen before C.
25#
26do_test where3-1.1 {
27  execsql {
28    CREATE TABLE t1(a, b);
29    CREATE TABLE t2(p, q);
30    CREATE TABLE t3(x, y);
31
32    INSERT INTO t1 VALUES(111,'one');
33    INSERT INTO t1 VALUES(222,'two');
34    INSERT INTO t1 VALUES(333,'three');
35
36    INSERT INTO t2 VALUES(1,111);
37    INSERT INTO t2 VALUES(2,222);
38    INSERT INTO t2 VALUES(4,444);
39    CREATE INDEX t2i1 ON t2(p);
40
41    INSERT INTO t3 VALUES(999,'nine');
42    CREATE INDEX t3i1 ON t3(x);
43
44    SELECT * FROM t1, t2 LEFT JOIN t3 ON q=x WHERE p=2 AND a=q;
45  }
46} {222 two 2 222 {} {}}
47
48ifcapable explain&&!cursorhints {
49  do_test where3-1.1.1 {
50     explain_no_trace {SELECT * FROM t1, t2 LEFT JOIN t3 ON q=x
51                        WHERE p=2 AND a=q}
52  } [explain_no_trace {SELECT * FROM t1, t2 LEFT JOIN t3 ON x=q
53                        WHERE p=2 AND a=q}]
54}
55
56# Ticket #1830
57#
58# This is similar to the above but with the LEFT JOIN on the
59# other side.
60#
61do_test where3-1.2 {
62  execsql {
63    CREATE TABLE parent1(parent1key, child1key, Child2key, child3key);
64    CREATE TABLE child1 ( child1key NVARCHAR, value NVARCHAR );
65    CREATE UNIQUE INDEX PKIDXChild1 ON child1 ( child1key );
66    CREATE TABLE child2 ( child2key NVARCHAR, value NVARCHAR );
67
68    INSERT INTO parent1(parent1key,child1key,child2key)
69       VALUES ( 1, 'C1.1', 'C2.1' );
70    INSERT INTO child1 ( child1key, value ) VALUES ( 'C1.1', 'Value for C1.1' );
71    INSERT INTO child2 ( child2key, value ) VALUES ( 'C2.1', 'Value for C2.1' );
72
73    INSERT INTO parent1 ( parent1key, child1key, child2key )
74       VALUES ( 2, 'C1.2', 'C2.2' );
75    INSERT INTO child2 ( child2key, value ) VALUES ( 'C2.2', 'Value for C2.2' );
76
77    INSERT INTO parent1 ( parent1key, child1key, child2key )
78       VALUES ( 3, 'C1.3', 'C2.3' );
79    INSERT INTO child1 ( child1key, value ) VALUES ( 'C1.3', 'Value for C1.3' );
80    INSERT INTO child2 ( child2key, value ) VALUES ( 'C2.3', 'Value for C2.3' );
81
82    SELECT parent1.parent1key, child1.value, child2.value
83    FROM parent1
84    LEFT OUTER JOIN child1 ON child1.child1key = parent1.child1key
85    INNER JOIN child2 ON child2.child2key = parent1.child2key;
86  }
87} {1 {Value for C1.1} {Value for C2.1} 2 {} {Value for C2.2} 3 {Value for C1.3} {Value for C2.3}}
88
89ifcapable explain&&!cursorhints {
90  do_test where3-1.2.1 {
91     explain_no_trace {
92       SELECT parent1.parent1key, child1.value, child2.value
93       FROM parent1
94       LEFT OUTER JOIN child1 ON child1.child1key = parent1.child1key
95       INNER JOIN child2 ON child2.child2key = parent1.child2key;
96     }
97  } [explain_no_trace {
98       SELECT parent1.parent1key, child1.value, child2.value
99       FROM parent1
100       LEFT OUTER JOIN child1 ON parent1.child1key = child1.child1key
101       INNER JOIN child2 ON child2.child2key = parent1.child2key;
102     }]
103}
104
105# This procedure executes the SQL.  Then it appends
106# the names of the table and index used
107#
108proc queryplan {sql} {
109  set ::sqlite_sort_count 0
110  set data [execsql $sql]
111  set eqp [execsql "EXPLAIN QUERY PLAN $sql"]
112  # puts eqp=$eqp
113  foreach {a b c x} $eqp {
114    if {[regexp { TABLE (\w+ AS )?(\w+) USING.* INDEX (\w+)\y} \
115        $x all as tab idx]} {
116      lappend data $tab $idx
117    } elseif {[regexp { TABLE (\w+ AS )?(\w+)\y} $x all as tab]} {
118      lappend data $tab *
119    }
120  }
121  return $data
122}
123
124
125# If you have a from clause of the form:   A B C left join D
126# then make sure the query optimizer is able to reorder the
127# A B C part anyway it wants.
128#
129# Following the fix to ticket #1652, there was a time when
130# the C table would not reorder.  So the following reorderings
131# were possible:
132#
133#            A B C left join D
134#            B A C left join D
135#
136# But these reorders were not allowed
137#
138#            C A B left join D
139#            A C B left join D
140#            C B A left join D
141#            B C A left join D
142#
143# The following tests are here to verify that the latter four
144# reorderings are allowed again.
145#
146do_test where3-2.1 {
147  execsql {
148    CREATE TABLE tA(apk integer primary key, ax);
149    CREATE TABLE tB(bpk integer primary key, bx);
150    CREATE TABLE tC(cpk integer primary key, cx);
151    CREATE TABLE tD(dpk integer primary key, dx);
152  }
153  queryplan {
154    SELECT * FROM tA, tB, tC LEFT JOIN tD ON dpk=cx
155     WHERE cpk=bx AND bpk=ax
156  }
157} {tA * tB * tC * tD *}
158do_test where3-2.1.1 {
159  queryplan {
160    SELECT * FROM tA, tB, tC LEFT JOIN tD ON cx=dpk
161     WHERE cpk=bx AND bpk=ax
162  }
163} {tA * tB * tC * tD *}
164do_test where3-2.1.2 {
165  queryplan {
166    SELECT * FROM tA, tB, tC LEFT JOIN tD ON cx=dpk
167     WHERE bx=cpk AND bpk=ax
168  }
169} {tA * tB * tC * tD *}
170do_test where3-2.1.3 {
171  queryplan {
172    SELECT * FROM tA, tB, tC LEFT JOIN tD ON cx=dpk
173     WHERE bx=cpk AND ax=bpk
174  }
175} {tA * tB * tC * tD *}
176do_test where3-2.1.4 {
177  queryplan {
178    SELECT * FROM tA, tB, tC LEFT JOIN tD ON dpk=cx
179     WHERE bx=cpk AND ax=bpk
180  }
181} {tA * tB * tC * tD *}
182do_test where3-2.1.5 {
183  queryplan {
184    SELECT * FROM tA, tB, tC LEFT JOIN tD ON dpk=cx
185     WHERE cpk=bx AND ax=bpk
186  }
187} {tA * tB * tC * tD *}
188do_test where3-2.2 {
189  queryplan {
190    SELECT * FROM tA, tB, tC LEFT JOIN tD ON dpk=cx
191     WHERE cpk=bx AND apk=bx
192  }
193} {tB * tA * tC * tD *}
194do_test where3-2.3 {
195  queryplan {
196    SELECT * FROM tA, tB, tC LEFT JOIN tD ON dpk=cx
197     WHERE cpk=bx AND apk=bx
198  }
199} {tB * tA * tC * tD *}
200do_test where3-2.4 {
201  queryplan {
202    SELECT * FROM tA, tB, tC LEFT JOIN tD ON dpk=cx
203     WHERE apk=cx AND bpk=ax
204  }
205} {tC * tA * tB * tD *}
206do_test where3-2.5 {
207  queryplan {
208    SELECT * FROM tA, tB, tC LEFT JOIN tD ON dpk=cx
209     WHERE cpk=ax AND bpk=cx
210  }
211} {tA * tC * tB * tD *}
212do_test where3-2.6 {
213  queryplan {
214    SELECT * FROM tA, tB, tC LEFT JOIN tD ON dpk=cx
215     WHERE bpk=cx AND apk=bx
216  }
217} {tC * tB * tA * tD *}
218do_test where3-2.7 {
219  queryplan {
220    SELECT * FROM tA, tB, tC LEFT JOIN tD ON dpk=cx
221     WHERE cpk=bx AND apk=cx
222  }
223} {tB * tC * tA * tD *}
224
225# Ticket [13f033c865f878953]
226# If the outer loop must be a full table scan, do not let ANALYZE trick
227# the planner into use a table for the outer loop that might be indexable
228# if held until an inner loop.
229#
230do_execsql_test where3-3.0 {
231  CREATE TABLE t301(a INTEGER PRIMARY KEY,b,c);
232  CREATE INDEX t301c ON t301(c);
233  INSERT INTO t301 VALUES(1,2,3);
234  INSERT INTO t301 VALUES(2,2,3);
235  CREATE TABLE t302(x, y);
236  INSERT INTO t302 VALUES(4,5);
237  ANALYZE;
238  explain query plan SELECT * FROM t302, t301 WHERE t302.x=5 AND t301.a=t302.y;
239} {
240  0 0 0 {SCAN TABLE t302}
241  0 1 1 {SEARCH TABLE t301 USING INTEGER PRIMARY KEY (rowid=?)}
242}
243do_execsql_test where3-3.1 {
244  explain query plan
245  SELECT * FROM t301, t302 WHERE t302.x=5 AND t301.a=t302.y;
246} {
247  0 0 1 {SCAN TABLE t302}
248  0 1 0 {SEARCH TABLE t301 USING INTEGER PRIMARY KEY (rowid=?)}
249}
250do_execsql_test where3-3.2 {
251  SELECT * FROM t301 WHERE c=3 AND a IS NULL;
252} {}
253do_execsql_test where3-3.3 {
254  SELECT * FROM t301 WHERE c=3 AND a IS NOT NULL;
255} {1 2 3 2 2 3}
256
257if 0 {  # Query planner no longer does this
258# Verify that when there are multiple tables in a join which must be
259# full table scans that the query planner attempts put the table with
260# the fewest number of output rows as the outer loop.
261#
262do_execsql_test where3-4.0 {
263  CREATE TABLE t400(a INTEGER PRIMARY KEY, b, c);
264  CREATE TABLE t401(p INTEGER PRIMARY KEY, q, r);
265  CREATE TABLE t402(x INTEGER PRIMARY KEY, y, z);
266  EXPLAIN QUERY PLAN
267  SELECT * FROM t400, t401, t402 WHERE t402.z GLOB 'abc*';
268} {
269  0 0 2 {SCAN TABLE t402}
270  0 1 0 {SCAN TABLE t400}
271  0 2 1 {SCAN TABLE t401}
272}
273do_execsql_test where3-4.1 {
274  EXPLAIN QUERY PLAN
275  SELECT * FROM t400, t401, t402 WHERE t401.r GLOB 'abc*';
276} {
277  0 0 1 {SCAN TABLE t401}
278  0 1 0 {SCAN TABLE t400}
279  0 2 2 {SCAN TABLE t402}
280}
281do_execsql_test where3-4.2 {
282  EXPLAIN QUERY PLAN
283  SELECT * FROM t400, t401, t402 WHERE t400.c GLOB 'abc*';
284} {
285  0 0 0 {SCAN TABLE t400}
286  0 1 1 {SCAN TABLE t401}
287  0 2 2 {SCAN TABLE t402}
288}
289} ;# endif
290
291# Verify that a performance regression encountered by firefox
292# has been fixed.
293#
294do_execsql_test where3-5.0 {
295  CREATE TABLE aaa (id INTEGER PRIMARY KEY, type INTEGER,
296                    fk INTEGER DEFAULT NULL, parent INTEGER,
297                    position INTEGER, title LONGVARCHAR,
298                    keyword_id INTEGER, folder_type TEXT,
299                    dateAdded INTEGER, lastModified INTEGER);
300  CREATE INDEX aaa_111 ON aaa (fk, type);
301  CREATE INDEX aaa_222 ON aaa (parent, position);
302  CREATE INDEX aaa_333 ON aaa (fk, lastModified);
303  CREATE TABLE bbb (id INTEGER PRIMARY KEY, type INTEGER,
304                    fk INTEGER DEFAULT NULL, parent INTEGER,
305                    position INTEGER, title LONGVARCHAR,
306                    keyword_id INTEGER, folder_type TEXT,
307                    dateAdded INTEGER, lastModified INTEGER);
308  CREATE INDEX bbb_111 ON bbb (fk, type);
309  CREATE INDEX bbb_222 ON bbb (parent, position);
310  CREATE INDEX bbb_333 ON bbb (fk, lastModified);
311
312  EXPLAIN QUERY PLAN
313   SELECT bbb.title AS tag_title
314     FROM aaa JOIN bbb ON bbb.id = aaa.parent
315    WHERE aaa.fk = 'constant'
316      AND LENGTH(bbb.title) > 0
317      AND bbb.parent = 4
318    ORDER BY bbb.title COLLATE NOCASE ASC;
319} {
320  0 0 0 {SEARCH TABLE aaa USING INDEX aaa_333 (fk=?)}
321  0 1 1 {SEARCH TABLE bbb USING INTEGER PRIMARY KEY (rowid=?)}
322  0 0 0 {USE TEMP B-TREE FOR ORDER BY}
323}
324do_execsql_test where3-5.1 {
325  EXPLAIN QUERY PLAN
326   SELECT bbb.title AS tag_title
327     FROM aaa JOIN aaa AS bbb ON bbb.id = aaa.parent
328    WHERE aaa.fk = 'constant'
329      AND LENGTH(bbb.title) > 0
330      AND bbb.parent = 4
331    ORDER BY bbb.title COLLATE NOCASE ASC;
332} {
333  0 0 0 {SEARCH TABLE aaa USING INDEX aaa_333 (fk=?)}
334  0 1 1 {SEARCH TABLE aaa AS bbb USING INTEGER PRIMARY KEY (rowid=?)}
335  0 0 0 {USE TEMP B-TREE FOR ORDER BY}
336}
337do_execsql_test where3-5.2 {
338  EXPLAIN QUERY PLAN
339   SELECT bbb.title AS tag_title
340     FROM bbb JOIN aaa ON bbb.id = aaa.parent
341    WHERE aaa.fk = 'constant'
342      AND LENGTH(bbb.title) > 0
343      AND bbb.parent = 4
344    ORDER BY bbb.title COLLATE NOCASE ASC;
345} {
346  0 0 1 {SEARCH TABLE aaa USING INDEX aaa_333 (fk=?)}
347  0 1 0 {SEARCH TABLE bbb USING INTEGER PRIMARY KEY (rowid=?)}
348  0 0 0 {USE TEMP B-TREE FOR ORDER BY}
349}
350do_execsql_test where3-5.3 {
351  EXPLAIN QUERY PLAN
352   SELECT bbb.title AS tag_title
353     FROM aaa AS bbb JOIN aaa ON bbb.id = aaa.parent
354    WHERE aaa.fk = 'constant'
355      AND LENGTH(bbb.title) > 0
356      AND bbb.parent = 4
357    ORDER BY bbb.title COLLATE NOCASE ASC;
358} {
359  0 0 1 {SEARCH TABLE aaa USING INDEX aaa_333 (fk=?)}
360  0 1 0 {SEARCH TABLE aaa AS bbb USING INTEGER PRIMARY KEY (rowid=?)}
361  0 0 0 {USE TEMP B-TREE FOR ORDER BY}
362}
363
364# Name resolution with NATURAL JOIN and USING
365#
366do_test where3-6.setup {
367  db eval {
368    CREATE TABLE t6w(a, w);
369    INSERT INTO t6w VALUES(1, 'w-one');
370    INSERT INTO t6w VALUES(2, 'w-two');
371    INSERT INTO t6w VALUES(9, 'w-nine');
372    CREATE TABLE t6x(a, x);
373    INSERT INTO t6x VALUES(1, 'x-one');
374    INSERT INTO t6x VALUES(3, 'x-three');
375    INSERT INTO t6x VALUES(9, 'x-nine');
376    CREATE TABLE t6y(a, y);
377    INSERT INTO t6y VALUES(1, 'y-one');
378    INSERT INTO t6y VALUES(4, 'y-four');
379    INSERT INTO t6y VALUES(9, 'y-nine');
380    CREATE TABLE t6z(a, z);
381    INSERT INTO t6z VALUES(1, 'z-one');
382    INSERT INTO t6z VALUES(5, 'z-five');
383    INSERT INTO t6z VALUES(9, 'z-nine');
384  }
385} {}
386set cnt 0
387foreach predicate {
388   {}
389   {ORDER BY a}
390   {ORDER BY t6w.a}
391   {WHERE a>0}
392   {WHERE t6y.a>0}
393   {WHERE a>0 ORDER BY a}
394} {
395  incr cnt
396  do_test where3-6.$cnt.1 {
397    set sql "SELECT * FROM t6w NATURAL JOIN t6x NATURAL JOIN t6y"
398    append sql " NATURAL JOIN t6z "
399    append sql $::predicate
400    db eval $sql
401  } {1 w-one x-one y-one z-one 9 w-nine x-nine y-nine z-nine}
402  do_test where3-6.$cnt.2 {
403    set sql "SELECT * FROM t6w JOIN t6x USING(a) JOIN t6y USING(a)"
404    append sql " JOIN t6z USING(a) "
405    append sql $::predicate
406    db eval $sql
407  } {1 w-one x-one y-one z-one 9 w-nine x-nine y-nine z-nine}
408  do_test where3-6.$cnt.3 {
409    set sql "SELECT * FROM t6w NATURAL JOIN t6x JOIN t6y USING(a)"
410    append sql " JOIN t6z USING(a) "
411    append sql $::predicate
412    db eval $sql
413  } {1 w-one x-one y-one z-one 9 w-nine x-nine y-nine z-nine}
414  do_test where3-6.$cnt.4 {
415    set sql "SELECT * FROM t6w JOIN t6x USING(a) NATURAL JOIN t6y"
416    append sql " JOIN t6z USING(a) "
417    append sql $::predicate
418    db eval $sql
419  } {1 w-one x-one y-one z-one 9 w-nine x-nine y-nine z-nine}
420  do_test where3-6.$cnt.5 {
421    set sql "SELECT * FROM t6w JOIN t6x USING(a) JOIN t6y USING(a)"
422    append sql " NATURAL JOIN t6z "
423    append sql $::predicate
424    db eval $sql
425  } {1 w-one x-one y-one z-one 9 w-nine x-nine y-nine z-nine}
426  do_test where3-6.$cnt.6 {
427    set sql "SELECT * FROM t6w JOIN t6x USING(a) NATURAL JOIN t6y"
428    append sql " NATURAL JOIN t6z "
429    append sql $::predicate
430    db eval $sql
431  } {1 w-one x-one y-one z-one 9 w-nine x-nine y-nine z-nine}
432  do_test where3-6.$cnt.7 {
433    set sql "SELECT * FROM t6w NATURAL JOIN t6x JOIN t6y USING(a)"
434    append sql " NATURAL JOIN t6z "
435    append sql $::predicate
436    db eval $sql
437  } {1 w-one x-one y-one z-one 9 w-nine x-nine y-nine z-nine}
438  do_test where3-6.$cnt.8 {
439    set sql "SELECT * FROM t6w NATURAL JOIN t6x NATURAL JOIN t6y"
440    append sql " JOIN t6z USING(a) "
441    append sql $::predicate
442    db eval $sql
443  } {1 w-one x-one y-one z-one 9 w-nine x-nine y-nine z-nine}
444}
445
446do_execsql_test where3-7-setup {
447  CREATE TABLE t71(x1 INTEGER PRIMARY KEY, y1);
448  CREATE TABLE t72(x2 INTEGER PRIMARY KEY, y2);
449  CREATE TABLE t73(x3, y3);
450  CREATE TABLE t74(x4, y4);
451  INSERT INTO t71 VALUES(123,234);
452  INSERT INTO t72 VALUES(234,345);
453  INSERT INTO t73 VALUES(123,234);
454  INSERT INTO t74 VALUES(234,345);
455  INSERT INTO t74 VALUES(234,678);
456} {}
457foreach disabled_opt {none omit-noop-join all} {
458  optimization_control db all 1
459  optimization_control db $disabled_opt 0
460  do_execsql_test where3-7.$disabled_opt.1 {
461    SELECT x1 FROM t71 LEFT JOIN t72 ON x2=y1;
462  } {123}
463  do_execsql_test where3-7.$disabled_opt.2 {
464    SELECT x1 FROM t71 LEFT JOIN t72 ON x2=y1 WHERE y2 IS NULL;
465  } {}
466  do_execsql_test where3-7.$disabled_opt.3 {
467    SELECT x1 FROM t71 LEFT JOIN t72 ON x2=y1 WHERE y2 IS NOT NULL;
468  } {123}
469  do_execsql_test where3-7.$disabled_opt.4 {
470    SELECT x1 FROM t71 LEFT JOIN t72 ON x2=y1 AND y2 IS NULL;
471  } {123}
472  do_execsql_test where3-7.$disabled_opt.5 {
473    SELECT x1 FROM t71 LEFT JOIN t72 ON x2=y1 AND y2 IS NOT NULL;
474  } {123}
475  do_execsql_test where3-7.$disabled_opt.6 {
476    SELECT x3 FROM t73 LEFT JOIN t72 ON x2=y3;
477  } {123}
478  do_execsql_test where3-7.$disabled_opt.7 {
479    SELECT DISTINCT x3 FROM t73 LEFT JOIN t72 ON x2=y3;
480  } {123}
481  do_execsql_test where3-7.$disabled_opt.8 {
482    SELECT x3 FROM t73 LEFT JOIN t74 ON x4=y3;
483  } {123 123}
484  do_execsql_test where3-7.$disabled_opt.9 {
485    SELECT DISTINCT x3 FROM t73 LEFT JOIN t74 ON x4=y3;
486  } {123}
487}
488
489
490finish_test
491