xref: /sqlite-3.40.0/test/select9.test (revision 8210233c)
19afe6847Sdanielk1977# 2008 June 24
29afe6847Sdanielk1977#
39afe6847Sdanielk1977# The author disclaims copyright to this source code.  In place of
49afe6847Sdanielk1977# a legal notice, here is a blessing:
59afe6847Sdanielk1977#
69afe6847Sdanielk1977#    May you do good and not evil.
79afe6847Sdanielk1977#    May you find forgiveness for yourself and forgive others.
89afe6847Sdanielk1977#    May you share freely, never taking more than you give.
99afe6847Sdanielk1977#
109afe6847Sdanielk1977#***********************************************************************
119afe6847Sdanielk1977# This file implements regression tests for SQLite library.
129afe6847Sdanielk1977#
134b86ef1dSdanielk1977# $Id: select9.test,v 1.4 2008/07/01 14:39:35 danielk1977 Exp $
149afe6847Sdanielk1977
159afe6847Sdanielk1977# The tests in this file are focused on test compound SELECT statements
169afe6847Sdanielk1977# that have any or all of an ORDER BY, LIMIT or OFFSET clauses. As of
179afe6847Sdanielk1977# version 3.6.0, SQLite contains code to use SQL indexes where possible
189afe6847Sdanielk1977# to optimize such statements.
199afe6847Sdanielk1977#
209afe6847Sdanielk1977
219afe6847Sdanielk1977# TODO Points:
229afe6847Sdanielk1977#
239afe6847Sdanielk1977#   * Are there any "column affinity" issues to consider?
249afe6847Sdanielk1977
259afe6847Sdanielk1977set testdir [file dirname $argv0]
269afe6847Sdanielk1977source $testdir/tester.tcl
279afe6847Sdanielk1977
289afe6847Sdanielk1977#-------------------------------------------------------------------------
299afe6847Sdanielk1977# test_compound_select TESTNAME SELECT RESULT
309afe6847Sdanielk1977#
319afe6847Sdanielk1977#   This command is used to run multiple LIMIT/OFFSET test cases based on
329afe6847Sdanielk1977#   the single SELECT statement passed as the second argument. The SELECT
339afe6847Sdanielk1977#   statement may not contain a LIMIT or OFFSET clause. This proc tests
349afe6847Sdanielk1977#   many statements of the form:
359afe6847Sdanielk1977#
369afe6847Sdanielk1977#     "$SELECT limit $X offset $Y"
379afe6847Sdanielk1977#
389afe6847Sdanielk1977#   for various values of $X and $Y.
399afe6847Sdanielk1977#
409afe6847Sdanielk1977#   The third argument, $RESULT, should contain the expected result of
419afe6847Sdanielk1977#   the command [execsql $SELECT].
429afe6847Sdanielk1977#
439afe6847Sdanielk1977#   The first argument, $TESTNAME, is used as the base test case name to
449afe6847Sdanielk1977#   pass to [do_test] for each individual LIMIT OFFSET test case.
459afe6847Sdanielk1977#
469afe6847Sdanielk1977proc test_compound_select {testname sql result} {
479afe6847Sdanielk1977
489afe6847Sdanielk1977  set nCol 1
499afe6847Sdanielk1977  db eval $sql A {
509afe6847Sdanielk1977    set nCol [llength $A(*)]
519afe6847Sdanielk1977    break
529afe6847Sdanielk1977  }
539afe6847Sdanielk1977  set nRow [expr {[llength $result] / $nCol}]
549afe6847Sdanielk1977
559afe6847Sdanielk1977  set ::compound_sql $sql
569afe6847Sdanielk1977  do_test $testname {
579afe6847Sdanielk1977    execsql $::compound_sql
589afe6847Sdanielk1977  } $result
599afe6847Sdanielk1977#return
609afe6847Sdanielk1977
619afe6847Sdanielk1977  set iLimitIncr  1
629afe6847Sdanielk1977  set iOffsetIncr 1
63430e74cdSdan  if {[info exists ::G(isquick)] && $::G(isquick) && $nRow>=5} {
646fb6444cSdanielk1977    set iOffsetIncr [expr $nRow / 5]
656fb6444cSdanielk1977    set iLimitIncr [expr $nRow / 5]
666fb6444cSdanielk1977  }
679afe6847Sdanielk1977
686fb6444cSdanielk1977  set iLimitEnd   [expr $nRow+$iLimitIncr]
696fb6444cSdanielk1977  set iOffsetEnd  [expr $nRow+$iOffsetIncr]
706fb6444cSdanielk1977
716fb6444cSdanielk1977  for {set iOffset 0} {$iOffset < $iOffsetEnd} {incr iOffset $iOffsetIncr} {
726fb6444cSdanielk1977    for {set iLimit 0} {$iLimit < $iLimitEnd} {incr iLimit} {
739afe6847Sdanielk1977
749afe6847Sdanielk1977      set ::compound_sql "$sql LIMIT $iLimit"
759afe6847Sdanielk1977      if {$iOffset != 0} {
769afe6847Sdanielk1977        append ::compound_sql " OFFSET $iOffset"
779afe6847Sdanielk1977      }
789afe6847Sdanielk1977
799afe6847Sdanielk1977      set iStart [expr {$iOffset*$nCol}]
809afe6847Sdanielk1977      set iEnd [expr {($iOffset*$nCol) + ($iLimit*$nCol) -1}]
819afe6847Sdanielk1977
829afe6847Sdanielk1977      do_test $testname.limit=$iLimit.offset=$iOffset {
839afe6847Sdanielk1977        execsql $::compound_sql
849afe6847Sdanielk1977      } [lrange $result $iStart $iEnd]
859afe6847Sdanielk1977    }
869afe6847Sdanielk1977  }
879afe6847Sdanielk1977}
889afe6847Sdanielk1977
899afe6847Sdanielk1977#-------------------------------------------------------------------------
909afe6847Sdanielk1977# test_compound_select_flippable TESTNAME SELECT RESULT
919afe6847Sdanielk1977#
929afe6847Sdanielk1977#   This command is for testing statements of the form:
939afe6847Sdanielk1977#
949afe6847Sdanielk1977#     <simple select 1> <compound op> <simple select 2> ORDER BY <order by>
959afe6847Sdanielk1977#
969afe6847Sdanielk1977#   where each <simple select> is a simple (non-compound) select statement
979afe6847Sdanielk1977#   and <compound op> is one of "INTERSECT", "UNION ALL" or "UNION".
989afe6847Sdanielk1977#
999afe6847Sdanielk1977#   This proc calls [test_compound_select] twice, once with the select
1009afe6847Sdanielk1977#   statement as it is passed to this command, and once with the positions
1019afe6847Sdanielk1977#   of <select statement 1> and <select statement 2> exchanged.
1029afe6847Sdanielk1977#
1039afe6847Sdanielk1977proc test_compound_select_flippable {testname sql result} {
1049afe6847Sdanielk1977  test_compound_select $testname $sql $result
1059afe6847Sdanielk1977
1069afe6847Sdanielk1977  set select [string trim $sql]
1079afe6847Sdanielk1977  set RE {(.*)(UNION ALL|INTERSECT|UNION)(.*)(ORDER BY.*)}
1089afe6847Sdanielk1977  set rc [regexp $RE $select -> s1 op s2 order_by]
1099afe6847Sdanielk1977  if {!$rc} {error "Statement is unflippable: $select"}
1109afe6847Sdanielk1977
1119afe6847Sdanielk1977  set flipsql "$s2 $op $s1 $order_by"
1129afe6847Sdanielk1977  test_compound_select $testname.flipped $flipsql $result
1139afe6847Sdanielk1977}
1149afe6847Sdanielk1977
1159afe6847Sdanielk1977#############################################################################
1169afe6847Sdanielk1977# Begin tests.
1179afe6847Sdanielk1977#
1189afe6847Sdanielk1977
1199afe6847Sdanielk1977# Create and populate a sample database.
1209afe6847Sdanielk1977#
1219afe6847Sdanielk1977do_test select9-1.0 {
1229afe6847Sdanielk1977  execsql {
1239afe6847Sdanielk1977    CREATE TABLE t1(a, b, c);
1249afe6847Sdanielk1977    CREATE TABLE t2(d, e, f);
1259afe6847Sdanielk1977    BEGIN;
1269afe6847Sdanielk1977      INSERT INTO t1 VALUES(1,  'one',   'I');
1279afe6847Sdanielk1977      INSERT INTO t1 VALUES(3,  NULL,    NULL);
1289afe6847Sdanielk1977      INSERT INTO t1 VALUES(5,  'five',  'V');
1299afe6847Sdanielk1977      INSERT INTO t1 VALUES(7,  'seven', 'VII');
1309afe6847Sdanielk1977      INSERT INTO t1 VALUES(9,  NULL,    NULL);
1319afe6847Sdanielk1977      INSERT INTO t1 VALUES(2,  'two',   'II');
1329afe6847Sdanielk1977      INSERT INTO t1 VALUES(4,  'four',  'IV');
1339afe6847Sdanielk1977      INSERT INTO t1 VALUES(6,  NULL,    NULL);
1349afe6847Sdanielk1977      INSERT INTO t1 VALUES(8,  'eight', 'VIII');
1359afe6847Sdanielk1977      INSERT INTO t1 VALUES(10, 'ten',   'X');
1369afe6847Sdanielk1977
1379afe6847Sdanielk1977      INSERT INTO t2 VALUES(1,  'two',      'IV');
1389afe6847Sdanielk1977      INSERT INTO t2 VALUES(2,  'four',     'VIII');
1399afe6847Sdanielk1977      INSERT INTO t2 VALUES(3,  NULL,       NULL);
1409afe6847Sdanielk1977      INSERT INTO t2 VALUES(4,  'eight',    'XVI');
1419afe6847Sdanielk1977      INSERT INTO t2 VALUES(5,  'ten',      'XX');
1429afe6847Sdanielk1977      INSERT INTO t2 VALUES(6,  NULL,       NULL);
1439afe6847Sdanielk1977      INSERT INTO t2 VALUES(7,  'fourteen', 'XXVIII');
1449afe6847Sdanielk1977      INSERT INTO t2 VALUES(8,  'sixteen',  'XXXII');
1459afe6847Sdanielk1977      INSERT INTO t2 VALUES(9,  NULL,       NULL);
1469afe6847Sdanielk1977      INSERT INTO t2 VALUES(10, 'twenty',   'XL');
1479afe6847Sdanielk1977
1489afe6847Sdanielk1977    COMMIT;
1499afe6847Sdanielk1977  }
1509afe6847Sdanielk1977} {}
1519afe6847Sdanielk1977
1529afe6847Sdanielk1977# Each iteration of this loop runs the same tests with a different set
1539afe6847Sdanielk1977# of indexes present within the database schema. The data returned by
1549afe6847Sdanielk1977# the compound SELECT statements in the test cases should be the same
1559afe6847Sdanielk1977# in each case.
1569afe6847Sdanielk1977#
1579afe6847Sdanielk1977set iOuterLoop 1
1589afe6847Sdanielk1977foreach indexes [list {
1599afe6847Sdanielk1977  /* Do not create any indexes. */
1609afe6847Sdanielk1977} {
1619afe6847Sdanielk1977  CREATE INDEX i1 ON t1(a)
1629afe6847Sdanielk1977} {
1639afe6847Sdanielk1977  CREATE INDEX i2 ON t1(b)
1649afe6847Sdanielk1977} {
1659afe6847Sdanielk1977  CREATE INDEX i3 ON t2(d)
1669afe6847Sdanielk1977} {
1679afe6847Sdanielk1977  CREATE INDEX i4 ON t2(e)
1689afe6847Sdanielk1977}] {
1699afe6847Sdanielk1977
1709afe6847Sdanielk1977  do_test select9-1.$iOuterLoop.1 {
1719afe6847Sdanielk1977    execsql $indexes
1729afe6847Sdanielk1977  } {}
1739afe6847Sdanielk1977
1749afe6847Sdanielk1977  # Test some 2-way UNION ALL queries. No WHERE clauses.
1759afe6847Sdanielk1977  #
1769afe6847Sdanielk1977  test_compound_select select9-1.$iOuterLoop.2 {
1779afe6847Sdanielk1977    SELECT a, b FROM t1 UNION ALL SELECT d, e FROM t2
1789afe6847Sdanielk1977  } {1 one 3 {} 5 five 7 seven 9 {} 2 two 4 four 6 {} 8 eight 10 ten 1 two 2 four 3 {} 4 eight 5 ten 6 {} 7 fourteen 8 sixteen 9 {} 10 twenty}
1799afe6847Sdanielk1977  test_compound_select select9-1.$iOuterLoop.3 {
1809afe6847Sdanielk1977    SELECT a, b FROM t1 UNION ALL SELECT d, e FROM t2 ORDER BY 1
1819afe6847Sdanielk1977  } {1 one 1 two 2 two 2 four 3 {} 3 {} 4 four 4 eight 5 five 5 ten 6 {} 6 {} 7 seven 7 fourteen 8 eight 8 sixteen 9 {} 9 {} 10 ten 10 twenty}
1829afe6847Sdanielk1977  test_compound_select select9-1.$iOuterLoop.4 {
1839afe6847Sdanielk1977    SELECT a, b FROM t1 UNION ALL SELECT d, e FROM t2 ORDER BY 2
1849afe6847Sdanielk1977  } {3 {} 9 {} 6 {} 3 {} 6 {} 9 {} 8 eight 4 eight 5 five 4 four 2 four 7 fourteen 1 one 7 seven 8 sixteen 10 ten 5 ten 10 twenty 2 two 1 two}
1859afe6847Sdanielk1977  test_compound_select_flippable select9-1.$iOuterLoop.5 {
1869afe6847Sdanielk1977    SELECT a, b FROM t1 UNION ALL SELECT d, e FROM t2 ORDER BY 1, 2
1879afe6847Sdanielk1977  } {1 one 1 two 2 four 2 two 3 {} 3 {} 4 eight 4 four 5 five 5 ten 6 {} 6 {} 7 fourteen 7 seven 8 eight 8 sixteen 9 {} 9 {} 10 ten 10 twenty}
1889afe6847Sdanielk1977  test_compound_select_flippable select9-1.$iOuterLoop.6 {
1899afe6847Sdanielk1977    SELECT a, b FROM t1 UNION ALL SELECT d, e FROM t2 ORDER BY 2, 1
1909afe6847Sdanielk1977  } {3 {} 3 {} 6 {} 6 {} 9 {} 9 {} 4 eight 8 eight 5 five 2 four 4 four 7 fourteen 1 one 7 seven 8 sixteen 5 ten 10 ten 10 twenty 1 two 2 two}
1919afe6847Sdanielk1977
1929afe6847Sdanielk1977  # Test some 2-way UNION queries.
1939afe6847Sdanielk1977  #
1949afe6847Sdanielk1977  test_compound_select select9-1.$iOuterLoop.7 {
1959afe6847Sdanielk1977    SELECT a, b FROM t1 UNION SELECT d, e FROM t2
1969afe6847Sdanielk1977  } {1 one 1 two 2 four 2 two 3 {} 4 eight 4 four 5 five 5 ten 6 {} 7 fourteen 7 seven 8 eight 8 sixteen 9 {} 10 ten 10 twenty}
1979afe6847Sdanielk1977
1989afe6847Sdanielk1977  test_compound_select select9-1.$iOuterLoop.8 {
1999afe6847Sdanielk1977    SELECT a, b FROM t1 UNION SELECT d, e FROM t2 ORDER BY 1
2009afe6847Sdanielk1977  } {1 one 1 two 2 four 2 two 3 {} 4 eight 4 four 5 five 5 ten 6 {} 7 fourteen 7 seven 8 eight 8 sixteen 9 {} 10 ten 10 twenty}
2019afe6847Sdanielk1977
2029afe6847Sdanielk1977  test_compound_select select9-1.$iOuterLoop.9 {
2039afe6847Sdanielk1977    SELECT a, b FROM t1 UNION SELECT d, e FROM t2 ORDER BY 2
2049afe6847Sdanielk1977  } {3 {} 6 {} 9 {} 4 eight 8 eight 5 five 2 four 4 four 7 fourteen 1 one 7 seven 8 sixteen 5 ten 10 ten 10 twenty 1 two 2 two}
2059afe6847Sdanielk1977
2069afe6847Sdanielk1977  test_compound_select_flippable select9-1.$iOuterLoop.10 {
2079afe6847Sdanielk1977    SELECT a, b FROM t1 UNION SELECT d, e FROM t2 ORDER BY 1, 2
2089afe6847Sdanielk1977  } {1 one 1 two 2 four 2 two 3 {} 4 eight 4 four 5 five 5 ten 6 {} 7 fourteen 7 seven 8 eight 8 sixteen 9 {} 10 ten 10 twenty}
2099afe6847Sdanielk1977
2109afe6847Sdanielk1977  test_compound_select_flippable select9-1.$iOuterLoop.11 {
2119afe6847Sdanielk1977    SELECT a, b FROM t1 UNION SELECT d, e FROM t2 ORDER BY 2, 1
2129afe6847Sdanielk1977  } {3 {} 6 {} 9 {} 4 eight 8 eight 5 five 2 four 4 four 7 fourteen 1 one 7 seven 8 sixteen 5 ten 10 ten 10 twenty 1 two 2 two}
2139afe6847Sdanielk1977
2149afe6847Sdanielk1977  # Test some 2-way INTERSECT queries.
2159afe6847Sdanielk1977  #
2169afe6847Sdanielk1977  test_compound_select select9-1.$iOuterLoop.11 {
2179afe6847Sdanielk1977    SELECT a, b FROM t1 INTERSECT SELECT d, e FROM t2
2189afe6847Sdanielk1977  } {3 {} 6 {} 9 {}}
2199afe6847Sdanielk1977  test_compound_select_flippable select9-1.$iOuterLoop.12 {
2209afe6847Sdanielk1977    SELECT a, b FROM t1 INTERSECT SELECT d, e FROM t2 ORDER BY 1
2219afe6847Sdanielk1977  } {3 {} 6 {} 9 {}}
2229afe6847Sdanielk1977  test_compound_select select9-1.$iOuterLoop.13 {
2239afe6847Sdanielk1977    SELECT a, b FROM t1 INTERSECT SELECT d, e FROM t2 ORDER BY 2
2249afe6847Sdanielk1977  } {3 {} 6 {} 9 {}}
2259afe6847Sdanielk1977  test_compound_select_flippable select9-1.$iOuterLoop.14 {
2269afe6847Sdanielk1977    SELECT a, b FROM t1 INTERSECT SELECT d, e FROM t2 ORDER BY 2, 1
2279afe6847Sdanielk1977  } {3 {} 6 {} 9 {}}
2289afe6847Sdanielk1977  test_compound_select_flippable select9-1.$iOuterLoop.15 {
2299afe6847Sdanielk1977    SELECT a, b FROM t1 INTERSECT SELECT d, e FROM t2 ORDER BY 1, 2
2309afe6847Sdanielk1977  } {3 {} 6 {} 9 {}}
2319afe6847Sdanielk1977
2329afe6847Sdanielk1977  # Test some 2-way EXCEPT queries.
2339afe6847Sdanielk1977  #
2349afe6847Sdanielk1977  test_compound_select select9-1.$iOuterLoop.16 {
2359afe6847Sdanielk1977    SELECT a, b FROM t1 EXCEPT SELECT d, e FROM t2
2369afe6847Sdanielk1977  } {1 one 2 two 4 four 5 five 7 seven 8 eight 10 ten}
2379afe6847Sdanielk1977
2389afe6847Sdanielk1977  test_compound_select select9-1.$iOuterLoop.17 {
2399afe6847Sdanielk1977    SELECT a, b FROM t1 EXCEPT SELECT d, e FROM t2 ORDER BY 1
2409afe6847Sdanielk1977  } {1 one 2 two 4 four 5 five 7 seven 8 eight 10 ten}
2419afe6847Sdanielk1977
2429afe6847Sdanielk1977  test_compound_select select9-1.$iOuterLoop.18 {
2439afe6847Sdanielk1977    SELECT a, b FROM t1 EXCEPT SELECT d, e FROM t2 ORDER BY 2
2449afe6847Sdanielk1977  } {8 eight 5 five 4 four 1 one 7 seven 10 ten 2 two}
2459afe6847Sdanielk1977
2469afe6847Sdanielk1977  test_compound_select select9-1.$iOuterLoop.19 {
2479afe6847Sdanielk1977    SELECT a, b FROM t1 EXCEPT SELECT d, e FROM t2 ORDER BY 1, 2
2489afe6847Sdanielk1977  } {1 one 2 two 4 four 5 five 7 seven 8 eight 10 ten}
2499afe6847Sdanielk1977
2509afe6847Sdanielk1977  test_compound_select select9-1.$iOuterLoop.20 {
2519afe6847Sdanielk1977    SELECT a, b FROM t1 EXCEPT SELECT d, e FROM t2 ORDER BY 2, 1
2529afe6847Sdanielk1977  } {8 eight 5 five 4 four 1 one 7 seven 10 ten 2 two}
2539afe6847Sdanielk1977
2549afe6847Sdanielk1977  incr iOuterLoop
2559afe6847Sdanielk1977}
2569afe6847Sdanielk1977
2576fb6444cSdanielk1977do_test select9-2.0 {
2586fb6444cSdanielk1977  execsql {
2596fb6444cSdanielk1977    DROP INDEX i1;
2606fb6444cSdanielk1977    DROP INDEX i2;
2616fb6444cSdanielk1977    DROP INDEX i3;
2626fb6444cSdanielk1977    DROP INDEX i4;
2636fb6444cSdanielk1977  }
2646fb6444cSdanielk1977} {}
2659afe6847Sdanielk1977
2666fb6444cSdanielk1977proc reverse {lhs rhs} {
2676fb6444cSdanielk1977  return [string compare $rhs $lhs]
2686fb6444cSdanielk1977}
2696fb6444cSdanielk1977db collate reverse reverse
2706fb6444cSdanielk1977
2716fb6444cSdanielk1977# This loop is similar to the previous one (test cases select9-1.*)
2726fb6444cSdanielk1977# except that the simple select statements have WHERE clauses attached
2736fb6444cSdanielk1977# to them. Sometimes the WHERE clause may be satisfied using the same
2746fb6444cSdanielk1977# index used for ORDER BY, sometimes not.
2756fb6444cSdanielk1977#
2766fb6444cSdanielk1977set iOuterLoop 1
2776fb6444cSdanielk1977foreach indexes [list {
2786fb6444cSdanielk1977  /* Do not create any indexes. */
2796fb6444cSdanielk1977} {
2806fb6444cSdanielk1977  CREATE INDEX i1 ON t1(a)
2816fb6444cSdanielk1977} {
2826fb6444cSdanielk1977  DROP INDEX i1;
2836fb6444cSdanielk1977  CREATE INDEX i1 ON t1(b, a)
2846fb6444cSdanielk1977} {
2856fb6444cSdanielk1977  CREATE INDEX i2 ON t2(d DESC, e COLLATE REVERSE ASC);
2866fb6444cSdanielk1977} {
2876fb6444cSdanielk1977  CREATE INDEX i3 ON t1(a DESC);
2886fb6444cSdanielk1977}] {
2896fb6444cSdanielk1977  do_test select9-2.$iOuterLoop.1 {
2906fb6444cSdanielk1977    execsql $indexes
2916fb6444cSdanielk1977  } {}
2926fb6444cSdanielk1977
2936fb6444cSdanielk1977  test_compound_select_flippable select9-2.$iOuterLoop.2 {
2946fb6444cSdanielk1977    SELECT * FROM t1 WHERE a<5 UNION SELECT * FROM t2 WHERE d>=5 ORDER BY 1
2956fb6444cSdanielk1977  } {1 one I 2 two II 3 {} {} 4 four IV 5 ten XX 6 {} {} 7 fourteen XXVIII 8 sixteen XXXII 9 {} {} 10 twenty XL}
2966fb6444cSdanielk1977
2976fb6444cSdanielk1977  test_compound_select_flippable select9-2.$iOuterLoop.2 {
2986fb6444cSdanielk1977    SELECT * FROM t1 WHERE a<5 UNION SELECT * FROM t2 WHERE d>=5 ORDER BY 2, 1
2996fb6444cSdanielk1977  } {3 {} {} 6 {} {} 9 {} {} 4 four IV 7 fourteen XXVIII 1 one I 8 sixteen XXXII 5 ten XX 10 twenty XL 2 two II}
3006fb6444cSdanielk1977
3016fb6444cSdanielk1977  test_compound_select_flippable select9-2.$iOuterLoop.3 {
3026fb6444cSdanielk1977    SELECT * FROM t1 WHERE a<5 UNION SELECT * FROM t2 WHERE d>=5
3036fb6444cSdanielk1977    ORDER BY 2 COLLATE reverse, 1
3046fb6444cSdanielk1977  } {3 {} {} 6 {} {} 9 {} {} 2 two II 10 twenty XL 5 ten XX 8 sixteen XXXII 1 one I 7 fourteen XXVIII 4 four IV}
3056fb6444cSdanielk1977
3066fb6444cSdanielk1977  test_compound_select_flippable select9-2.$iOuterLoop.4 {
3076fb6444cSdanielk1977    SELECT * FROM t1 WHERE a<5 UNION ALL SELECT * FROM t2 WHERE d>=5 ORDER BY 1
3086fb6444cSdanielk1977  } {1 one I 2 two II 3 {} {} 4 four IV 5 ten XX 6 {} {} 7 fourteen XXVIII 8 sixteen XXXII 9 {} {} 10 twenty XL}
3096fb6444cSdanielk1977
3106fb6444cSdanielk1977  test_compound_select_flippable select9-2.$iOuterLoop.5 {
3116fb6444cSdanielk1977    SELECT * FROM t1 WHERE a<5 UNION ALL SELECT * FROM t2 WHERE d>=5 ORDER BY 2, 1
3126fb6444cSdanielk1977  } {3 {} {} 6 {} {} 9 {} {} 4 four IV 7 fourteen XXVIII 1 one I 8 sixteen XXXII 5 ten XX 10 twenty XL 2 two II}
3136fb6444cSdanielk1977
3146fb6444cSdanielk1977  test_compound_select_flippable select9-2.$iOuterLoop.6 {
3156fb6444cSdanielk1977    SELECT * FROM t1 WHERE a<5 UNION ALL SELECT * FROM t2 WHERE d>=5
3166fb6444cSdanielk1977    ORDER BY 2 COLLATE reverse, 1
3176fb6444cSdanielk1977  } {3 {} {} 6 {} {} 9 {} {} 2 two II 10 twenty XL 5 ten XX 8 sixteen XXXII 1 one I 7 fourteen XXVIII 4 four IV}
3186fb6444cSdanielk1977
3196fb6444cSdanielk1977  test_compound_select select9-2.$iOuterLoop.4 {
3206fb6444cSdanielk1977    SELECT a FROM t1 WHERE a<8 EXCEPT SELECT d FROM t2 WHERE d<=3 ORDER BY 1
3216fb6444cSdanielk1977  } {4 5 6 7}
3226fb6444cSdanielk1977
3236fb6444cSdanielk1977  test_compound_select select9-2.$iOuterLoop.4 {
3246fb6444cSdanielk1977    SELECT a FROM t1 WHERE a<8 INTERSECT SELECT d FROM t2 WHERE d<=3 ORDER BY 1
3256fb6444cSdanielk1977  } {1 2 3}
3266fb6444cSdanielk1977
3276fb6444cSdanielk1977}
3286fb6444cSdanielk1977
3297a8097b6Sdanielk1977do_test select9-2.X {
3307a8097b6Sdanielk1977  execsql {
3317a8097b6Sdanielk1977    DROP INDEX i1;
3327a8097b6Sdanielk1977    DROP INDEX i2;
3337a8097b6Sdanielk1977    DROP INDEX i3;
3347a8097b6Sdanielk1977  }
3357a8097b6Sdanielk1977} {}
3367a8097b6Sdanielk1977
3377a8097b6Sdanielk1977# This procedure executes the SQL.  Then it checks the generated program
3387a8097b6Sdanielk1977# for the SQL and appends a "nosort" to the result if the program contains the
3397a8097b6Sdanielk1977# SortCallback opcode.  If the program does not contain the SortCallback
3407a8097b6Sdanielk1977# opcode it appends "sort"
3417a8097b6Sdanielk1977#
3427a8097b6Sdanielk1977proc cksort {sql} {
3437a8097b6Sdanielk1977  set ::sqlite_sort_count 0
3447a8097b6Sdanielk1977  set data [execsql $sql]
3457a8097b6Sdanielk1977  if {$::sqlite_sort_count} {set x sort} {set x nosort}
3467a8097b6Sdanielk1977  lappend data $x
3477a8097b6Sdanielk1977  return $data
3487a8097b6Sdanielk1977}
3497a8097b6Sdanielk1977
3507a8097b6Sdanielk1977# If the right indexes exist, the following query:
3517a8097b6Sdanielk1977#
3527a8097b6Sdanielk1977#     SELECT t1.a FROM t1 UNION ALL SELECT t2.d FROM t2 ORDER BY 1
3537a8097b6Sdanielk1977#
3547a8097b6Sdanielk1977# can use indexes to run without doing a in-memory sort operation.
3557a8097b6Sdanielk1977# This block of tests (select9-3.*) is used to check if the same
3567a8097b6Sdanielk1977# is possible with:
3577a8097b6Sdanielk1977#
3587a8097b6Sdanielk1977#     CREATE VIEW v1 AS SELECT a FROM t1 UNION ALL SELECT d FROM t2
3597a8097b6Sdanielk1977#     SELECT a FROM v1 ORDER BY 1
3607a8097b6Sdanielk1977#
3614b86ef1dSdanielk1977# It turns out that it is.
3627a8097b6Sdanielk1977#
3637a8097b6Sdanielk1977do_test select9-3.1 {
3647a8097b6Sdanielk1977  cksort { SELECT a FROM t1 ORDER BY 1 }
3657a8097b6Sdanielk1977} {1 2 3 4 5 6 7 8 9 10 sort}
3667a8097b6Sdanielk1977do_test select9-3.2 {
3677a8097b6Sdanielk1977  execsql { CREATE INDEX i1 ON t1(a) }
3687a8097b6Sdanielk1977  cksort { SELECT a FROM t1 ORDER BY 1 }
3697a8097b6Sdanielk1977} {1 2 3 4 5 6 7 8 9 10 nosort}
3707a8097b6Sdanielk1977do_test select9-3.3 {
3717a8097b6Sdanielk1977  cksort { SELECT a FROM t1 UNION ALL SELECT d FROM t2 ORDER BY 1 LIMIT 5 }
3727a8097b6Sdanielk1977} {1 1 2 2 3 sort}
3737a8097b6Sdanielk1977do_test select9-3.4 {
3747a8097b6Sdanielk1977  execsql { CREATE INDEX i2 ON t2(d) }
3757a8097b6Sdanielk1977  cksort { SELECT a FROM t1 UNION ALL SELECT d FROM t2 ORDER BY 1 LIMIT 5 }
3767a8097b6Sdanielk1977} {1 1 2 2 3 nosort}
3777a8097b6Sdanielk1977do_test select9-3.5 {
3787a8097b6Sdanielk1977  execsql { CREATE VIEW v1 AS SELECT a FROM t1 UNION ALL SELECT d FROM t2 }
3797a8097b6Sdanielk1977  cksort { SELECT a FROM v1 ORDER BY 1 LIMIT 5 }
3804b86ef1dSdanielk1977} {1 1 2 2 3 nosort}
3817a8097b6Sdanielk1977do_test select9-3.X {
3827a8097b6Sdanielk1977  execsql {
3837a8097b6Sdanielk1977    DROP INDEX i1;
3847a8097b6Sdanielk1977    DROP INDEX i2;
3857a8097b6Sdanielk1977    DROP VIEW v1;
3867a8097b6Sdanielk1977  }
3877a8097b6Sdanielk1977} {}
3887a8097b6Sdanielk1977
3897a8097b6Sdanielk1977# This block of tests is the same as the preceding one, except that
3907a8097b6Sdanielk1977# "UNION" is tested instead of "UNION ALL".
3917a8097b6Sdanielk1977#
3927a8097b6Sdanielk1977do_test select9-4.1 {
3937a8097b6Sdanielk1977  cksort { SELECT a FROM t1 ORDER BY 1 }
3947a8097b6Sdanielk1977} {1 2 3 4 5 6 7 8 9 10 sort}
3957a8097b6Sdanielk1977do_test select9-4.2 {
3967a8097b6Sdanielk1977  execsql { CREATE INDEX i1 ON t1(a) }
3977a8097b6Sdanielk1977  cksort { SELECT a FROM t1 ORDER BY 1 }
3987a8097b6Sdanielk1977} {1 2 3 4 5 6 7 8 9 10 nosort}
3997a8097b6Sdanielk1977do_test select9-4.3 {
4007a8097b6Sdanielk1977  cksort { SELECT a FROM t1 UNION SELECT d FROM t2 ORDER BY 1 LIMIT 5 }
4017a8097b6Sdanielk1977} {1 2 3 4 5 sort}
4027a8097b6Sdanielk1977do_test select9-4.4 {
4037a8097b6Sdanielk1977  execsql { CREATE INDEX i2 ON t2(d) }
4047a8097b6Sdanielk1977  cksort { SELECT a FROM t1 UNION SELECT d FROM t2 ORDER BY 1 LIMIT 5 }
4057a8097b6Sdanielk1977} {1 2 3 4 5 nosort}
4067a8097b6Sdanielk1977do_test select9-4.5 {
4077a8097b6Sdanielk1977  execsql { CREATE VIEW v1 AS SELECT a FROM t1 UNION SELECT d FROM t2 }
4087a8097b6Sdanielk1977  cksort { SELECT a FROM v1 ORDER BY 1 LIMIT 5 }
4097a8097b6Sdanielk1977} {1 2 3 4 5 sort}
4107a8097b6Sdanielk1977do_test select9-4.X {
4117a8097b6Sdanielk1977  execsql {
4127a8097b6Sdanielk1977    DROP INDEX i1;
4137a8097b6Sdanielk1977    DROP INDEX i2;
4147a8097b6Sdanielk1977    DROP VIEW v1;
4157a8097b6Sdanielk1977  }
4167a8097b6Sdanielk1977} {}
4177a8097b6Sdanielk1977
41870331cd7Sdrh# Testing to make sure that queries involving a view of a compound select
41970331cd7Sdrh# are planned efficiently.  This detects a problem reported on the mailing
42070331cd7Sdrh# list on 2012-04-26.  See
42170331cd7Sdrh#
42270331cd7Sdrh#  http://www.mail-archive.com/sqlite-users%40sqlite.org/msg69746.html
42370331cd7Sdrh#
42470331cd7Sdrh# For additional information.
42570331cd7Sdrh#
42670331cd7Sdrhdo_test select9-5.1 {
42770331cd7Sdrh  db eval {
42870331cd7Sdrh    CREATE TABLE t51(x, y);
42970331cd7Sdrh    CREATE TABLE t52(x, y);
43070331cd7Sdrh    CREATE VIEW v5 as
43170331cd7Sdrh       SELECT x, y FROM t51
43270331cd7Sdrh       UNION ALL
43370331cd7Sdrh       SELECT x, y FROM t52;
43470331cd7Sdrh    CREATE INDEX t51x ON t51(x);
43570331cd7Sdrh    CREATE INDEX t52x ON t52(x);
43670331cd7Sdrh    EXPLAIN QUERY PLAN
43770331cd7Sdrh       SELECT * FROM v5 WHERE x='12345' ORDER BY y;
43870331cd7Sdrh  }
439*8210233cSdrh} {~/SCAN/}  ;# Uses indices with "*"
44070331cd7Sdrhdo_test select9-5.2 {
44170331cd7Sdrh  db eval {
44270331cd7Sdrh    EXPLAIN QUERY PLAN
44370331cd7Sdrh       SELECT x, y FROM v5 WHERE x='12345' ORDER BY y;
44470331cd7Sdrh  }
445*8210233cSdrh} {~/SCAN/}  ;# Uses indices with "x, y"
44670331cd7Sdrhdo_test select9-5.3 {
44770331cd7Sdrh  db eval {
44870331cd7Sdrh    EXPLAIN QUERY PLAN
44970331cd7Sdrh       SELECT x, y FROM v5 WHERE +x='12345' ORDER BY y;
45070331cd7Sdrh  }
451*8210233cSdrh} {/SCAN/}   ;# Full table scan if the "+x" prevents index usage.
45270331cd7Sdrh
4535e128b23Sdrh# 2013-07-09:  Ticket [490a4b7235624298]:
4545e128b23Sdrh# "WHERE 0" on the first element of a UNION causes an assertion fault
4555e128b23Sdrh#
4565e128b23Sdrhdo_execsql_test select9-6.1 {
4575e128b23Sdrh  CREATE TABLE t61(a);
4585e128b23Sdrh  CREATE TABLE t62(b);
4595e128b23Sdrh  INSERT INTO t61 VALUES(111);
4605e128b23Sdrh  INSERT INTO t62 VALUES(222);
4615e128b23Sdrh  SELECT a FROM t61 WHERE 0 UNION SELECT b FROM t62;
4625e128b23Sdrh} {222}
4635e128b23Sdrhdo_execsql_test select9-6.2 {
4645e128b23Sdrh  SELECT a FROM t61 WHERE 0 UNION ALL SELECT b FROM t62;
4655e128b23Sdrh} {222}
4665e128b23Sdrhdo_execsql_test select9-6.3 {
4675e128b23Sdrh  SELECT a FROM t61 UNION SELECT b FROM t62 WHERE 0;
4685e128b23Sdrh} {111}
4695e128b23Sdrh
4705e128b23Sdrh
4716fb6444cSdanielk1977
4726fb6444cSdanielk1977finish_test
473