xref: /sqlite-3.40.0/test/orderby1.test (revision 8210233c)
16b10a6a7Sdrh# 2012 Sept 27
26b10a6a7Sdrh#
36b10a6a7Sdrh# The author disclaims copyright to this source code.  In place of
46b10a6a7Sdrh# a legal notice, here is a blessing:
56b10a6a7Sdrh#
66b10a6a7Sdrh#    May you do good and not evil.
76b10a6a7Sdrh#    May you find forgiveness for yourself and forgive others.
86b10a6a7Sdrh#    May you share freely, never taking more than you give.
96b10a6a7Sdrh#
106b10a6a7Sdrh#***********************************************************************
116b10a6a7Sdrh# This file implements regression tests for SQLite library.  The
126b10a6a7Sdrh# focus of this file is testing that the optimizations that disable
136b10a6a7Sdrh# ORDER BY clauses when the natural order of a query is correct.
146b10a6a7Sdrh#
156b10a6a7Sdrh
166b10a6a7Sdrh
176b10a6a7Sdrhset testdir [file dirname $argv0]
186b10a6a7Sdrhsource $testdir/tester.tcl
196b10a6a7Sdrhset ::testprefix orderby1
206b10a6a7Sdrh
216b10a6a7Sdrh# Generate test data for a join.  Verify that the join gets the
226b10a6a7Sdrh# correct answer.
236b10a6a7Sdrh#
246b10a6a7Sdrhdo_test 1.0 {
256b10a6a7Sdrh  db eval {
266b10a6a7Sdrh    BEGIN;
276b10a6a7Sdrh    CREATE TABLE album(
286b10a6a7Sdrh      aid INTEGER PRIMARY KEY,
296b10a6a7Sdrh      title TEXT UNIQUE NOT NULL
306b10a6a7Sdrh    );
316b10a6a7Sdrh    CREATE TABLE track(
326b10a6a7Sdrh      tid INTEGER PRIMARY KEY,
336b10a6a7Sdrh      aid INTEGER NOT NULL REFERENCES album,
346b10a6a7Sdrh      tn INTEGER NOT NULL,
356b10a6a7Sdrh      name TEXT,
366b10a6a7Sdrh      UNIQUE(aid, tn)
376b10a6a7Sdrh    );
386b10a6a7Sdrh    INSERT INTO album VALUES(1, '1-one'), (2, '2-two'), (3, '3-three');
396b10a6a7Sdrh    INSERT INTO track VALUES
406b10a6a7Sdrh        (NULL, 1, 1, 'one-a'),
416b10a6a7Sdrh        (NULL, 2, 2, 'two-b'),
426b10a6a7Sdrh        (NULL, 3, 3, 'three-c'),
436b10a6a7Sdrh        (NULL, 1, 3, 'one-c'),
446b10a6a7Sdrh        (NULL, 2, 1, 'two-a'),
456b10a6a7Sdrh        (NULL, 3, 1, 'three-a');
466b10a6a7Sdrh    COMMIT;
476b10a6a7Sdrh  }
486b10a6a7Sdrh} {}
496b10a6a7Sdrhdo_test 1.1a {
506b10a6a7Sdrh  db eval {
51aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn
526b10a6a7Sdrh  }
536b10a6a7Sdrh} {one-a one-c two-a two-b three-a three-c}
546b10a6a7Sdrh
556b10a6a7Sdrh# Verify that the ORDER BY clause is optimized out
566b10a6a7Sdrh#
576b10a6a7Sdrhdo_test 1.1b {
586b10a6a7Sdrh  db eval {
596b10a6a7Sdrh    EXPLAIN QUERY PLAN
60782d68a4Sdrh    SELECT name FROM album CROSS JOIN track USING (aid) ORDER BY title, tn
616b10a6a7Sdrh  }
626b10a6a7Sdrh} {~/ORDER BY/}  ;# ORDER BY optimized out
636b10a6a7Sdrh
646b10a6a7Sdrh# The same query with ORDER BY clause optimization disabled via + operators
656b10a6a7Sdrh# should give exactly the same answer.
666b10a6a7Sdrh#
676b10a6a7Sdrhdo_test 1.2a {
686b10a6a7Sdrh  db eval {
69aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY +title, +tn
706b10a6a7Sdrh  }
716b10a6a7Sdrh} {one-a one-c two-a two-b three-a three-c}
726b10a6a7Sdrh
736b10a6a7Sdrh# The output is sorted manually in this case.
746b10a6a7Sdrh#
756b10a6a7Sdrhdo_test 1.2b {
766b10a6a7Sdrh  db eval {
776b10a6a7Sdrh    EXPLAIN QUERY PLAN
78aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY +title, +tn
796b10a6a7Sdrh  }
806b10a6a7Sdrh} {/ORDER BY/}   ;# separate sorting pass due to "+" on ORDER BY terms
816b10a6a7Sdrh
826b10a6a7Sdrh# The same query with ORDER BY optimizations turned off via built-in test.
836b10a6a7Sdrh#
846b10a6a7Sdrhdo_test 1.3a {
856b10a6a7Sdrh  optimization_control db order-by-idx-join 0
866b10a6a7Sdrh  db cache flush
876b10a6a7Sdrh  db eval {
88aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn
896b10a6a7Sdrh  }
906b10a6a7Sdrh} {one-a one-c two-a two-b three-a three-c}
916b10a6a7Sdrhdo_test 1.3b {
926b10a6a7Sdrh  db eval {
936b10a6a7Sdrh    EXPLAIN QUERY PLAN
94aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn
956b10a6a7Sdrh  }
966b10a6a7Sdrh} {/ORDER BY/}   ;# separate sorting pass due to disabled optimization
976b10a6a7Sdrhoptimization_control db all 1
986b10a6a7Sdrhdb cache flush
996b10a6a7Sdrh
1006b10a6a7Sdrh# Reverse order sorts
1016b10a6a7Sdrh#
1026b10a6a7Sdrhdo_test 1.4a {
1036b10a6a7Sdrh  db eval {
104aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY title DESC, tn
1056b10a6a7Sdrh  }
1066b10a6a7Sdrh} {three-a three-c two-a two-b one-a one-c}
1076b10a6a7Sdrhdo_test 1.4b {
1086b10a6a7Sdrh  db eval {
109aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY +title DESC, +tn
1106b10a6a7Sdrh  }
1116b10a6a7Sdrh} {three-a three-c two-a two-b one-a one-c}  ;# verify same order after sorting
1126b10a6a7Sdrhdo_test 1.4c {
1136b10a6a7Sdrh  db eval {
1146b10a6a7Sdrh    EXPLAIN QUERY PLAN
115aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY title DESC, tn
1166b10a6a7Sdrh  }
1174fe425adSdrh} {~/ORDER BY/}  ;# ORDER BY suppressed due to uniqueness constraints
1186b10a6a7Sdrh
1196b10a6a7Sdrhdo_test 1.5a {
1206b10a6a7Sdrh  db eval {
121aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn DESC
1226b10a6a7Sdrh  }
1236b10a6a7Sdrh} {one-c one-a two-b two-a three-c three-a}
1246b10a6a7Sdrhdo_test 1.5b {
1256b10a6a7Sdrh  db eval {
126aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY +title, +tn DESC
1276b10a6a7Sdrh  }
1286b10a6a7Sdrh} {one-c one-a two-b two-a three-c three-a}  ;# verify same order after sorting
1296b10a6a7Sdrhdo_test 1.5c {
1306b10a6a7Sdrh  db eval {
1316b10a6a7Sdrh    EXPLAIN QUERY PLAN
132aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn DESC
1336b10a6a7Sdrh  }
1344fe425adSdrh} {~/ORDER BY/}  ;# ORDER BY suppressed due to uniqueness constraints
1356b10a6a7Sdrh
1366b10a6a7Sdrhdo_test 1.6a {
1376b10a6a7Sdrh  db eval {
138aec93a1fSdrh    SELECT name FROM album CROSS JOIN track USING (aid)
139aec93a1fSdrh     ORDER BY title DESC, tn DESC
1406b10a6a7Sdrh  }
1416b10a6a7Sdrh} {three-c three-a two-b two-a one-c one-a}
1426b10a6a7Sdrhdo_test 1.6b {
1436b10a6a7Sdrh  db eval {
144aec93a1fSdrh    SELECT name FROM album CROSS JOIN track USING (aid)
145aec93a1fSdrh     ORDER BY +title DESC, +tn DESC
1466b10a6a7Sdrh  }
1476b10a6a7Sdrh} {three-c three-a two-b two-a one-c one-a}  ;# verify same order after sorting
1486b10a6a7Sdrhdo_test 1.6c {
1496b10a6a7Sdrh  db eval {
1506b10a6a7Sdrh    EXPLAIN QUERY PLAN
151aec93a1fSdrh    SELECT name FROM album CROSS JOIN track USING (aid)
152aec93a1fSdrh     ORDER BY title DESC, tn DESC
1536b10a6a7Sdrh  }
154aec93a1fSdrh} {~/ORDER BY/}  ;# ORDER BY
1556b10a6a7Sdrh
1566b10a6a7Sdrh
1575343b2d4Sdrh# Reconstruct the test data to use indices rather than integer primary keys.
1585343b2d4Sdrh#
1595343b2d4Sdrhdo_test 2.0 {
1605343b2d4Sdrh  db eval {
1615343b2d4Sdrh    BEGIN;
1625343b2d4Sdrh    DROP TABLE album;
1635343b2d4Sdrh    DROP TABLE track;
1645343b2d4Sdrh    CREATE TABLE album(
1655343b2d4Sdrh      aid INT PRIMARY KEY,
1665343b2d4Sdrh      title TEXT NOT NULL
1675343b2d4Sdrh    );
1685343b2d4Sdrh    CREATE INDEX album_i1 ON album(title, aid);
1695343b2d4Sdrh    CREATE TABLE track(
1705343b2d4Sdrh      aid INTEGER NOT NULL REFERENCES album,
1715343b2d4Sdrh      tn INTEGER NOT NULL,
1725343b2d4Sdrh      name TEXT,
1735343b2d4Sdrh      UNIQUE(aid, tn)
1745343b2d4Sdrh    );
175178eb61cSdrh    INSERT INTO album VALUES(1, '1-one'), (20, '2-two'), (3, '3-three');
1765343b2d4Sdrh    INSERT INTO track VALUES
1775343b2d4Sdrh        (1,  1, 'one-a'),
178178eb61cSdrh        (20, 2, 'two-b'),
1795343b2d4Sdrh        (3,  3, 'three-c'),
1805343b2d4Sdrh        (1,  3, 'one-c'),
181178eb61cSdrh        (20, 1, 'two-a'),
1825343b2d4Sdrh        (3,  1, 'three-a');
1835343b2d4Sdrh    COMMIT;
1845343b2d4Sdrh  }
1855343b2d4Sdrh} {}
1865343b2d4Sdrhdo_test 2.1a {
1875343b2d4Sdrh  db eval {
188aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn
1895343b2d4Sdrh  }
1905343b2d4Sdrh} {one-a one-c two-a two-b three-a three-c}
1915343b2d4Sdrh
1925343b2d4Sdrh# Verify that the ORDER BY clause is optimized out
1935343b2d4Sdrh#
1945343b2d4Sdrhdo_test 2.1b {
1955343b2d4Sdrh  db eval {
1965343b2d4Sdrh    EXPLAIN QUERY PLAN
197aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn
1985343b2d4Sdrh  }
199aec93a1fSdrh} {/ORDER BY/}  ;# ORDER BY required because of missing aid term in ORDER BY
200178eb61cSdrh
201178eb61cSdrhdo_test 2.1c {
202178eb61cSdrh  db eval {
203aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY title, aid, tn
204178eb61cSdrh  }
205178eb61cSdrh} {one-a one-c two-a two-b three-a three-c}
206178eb61cSdrhdo_test 2.1d {
207178eb61cSdrh  db eval {
208178eb61cSdrh    EXPLAIN QUERY PLAN
209aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY title, aid, tn
210178eb61cSdrh  }
211aec93a1fSdrh} {/ORDER BY/}  ;# ORDER BY required in this case
2125343b2d4Sdrh
2135343b2d4Sdrh# The same query with ORDER BY clause optimization disabled via + operators
2145343b2d4Sdrh# should give exactly the same answer.
2155343b2d4Sdrh#
2165343b2d4Sdrhdo_test 2.2a {
2175343b2d4Sdrh  db eval {
218aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY +title, +tn
2195343b2d4Sdrh  }
2205343b2d4Sdrh} {one-a one-c two-a two-b three-a three-c}
2215343b2d4Sdrh
2225343b2d4Sdrh# The output is sorted manually in this case.
2235343b2d4Sdrh#
2245343b2d4Sdrhdo_test 2.2b {
2255343b2d4Sdrh  db eval {
2265343b2d4Sdrh    EXPLAIN QUERY PLAN
227aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY +title, +tn
2285343b2d4Sdrh  }
2295343b2d4Sdrh} {/ORDER BY/}   ;# separate sorting pass due to "+" on ORDER BY terms
2305343b2d4Sdrh
2315343b2d4Sdrh# The same query with ORDER BY optimizations turned off via built-in test.
2325343b2d4Sdrh#
2335343b2d4Sdrhdo_test 2.3a {
2345343b2d4Sdrh  optimization_control db order-by-idx-join 0
2355343b2d4Sdrh  db cache flush
2365343b2d4Sdrh  db eval {
237aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn
2385343b2d4Sdrh  }
2395343b2d4Sdrh} {one-a one-c two-a two-b three-a three-c}
2405343b2d4Sdrhdo_test 2.3b {
2415343b2d4Sdrh  db eval {
2425343b2d4Sdrh    EXPLAIN QUERY PLAN
243aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn
2445343b2d4Sdrh  }
2455343b2d4Sdrh} {/ORDER BY/}   ;# separate sorting pass due to disabled optimization
2465343b2d4Sdrhoptimization_control db all 1
2475343b2d4Sdrhdb cache flush
2485343b2d4Sdrh
2495343b2d4Sdrh# Reverse order sorts
2505343b2d4Sdrh#
2515343b2d4Sdrhdo_test 2.4a {
2525343b2d4Sdrh  db eval {
253aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY title DESC, tn
2545343b2d4Sdrh  }
2555343b2d4Sdrh} {three-a three-c two-a two-b one-a one-c}
2565343b2d4Sdrhdo_test 2.4b {
2575343b2d4Sdrh  db eval {
258aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY +title DESC, +tn
2595343b2d4Sdrh  }
2605343b2d4Sdrh} {three-a three-c two-a two-b one-a one-c}  ;# verify same order after sorting
2615343b2d4Sdrhdo_test 2.4c {
2625343b2d4Sdrh  db eval {
2635343b2d4Sdrh    EXPLAIN QUERY PLAN
264aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY title DESC, tn
2655343b2d4Sdrh  }
266aec93a1fSdrh} {/ORDER BY/}  ;# separate sorting pass due to mixed DESC/ASC
2675343b2d4Sdrh
2685343b2d4Sdrh
2695343b2d4Sdrhdo_test 2.5a {
2705343b2d4Sdrh  db eval {
271aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn DESC
2725343b2d4Sdrh  }
2735343b2d4Sdrh} {one-c one-a two-b two-a three-c three-a}
2745343b2d4Sdrhdo_test 2.5b {
2755343b2d4Sdrh  db eval {
276aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY +title, +tn DESC
2775343b2d4Sdrh  }
2785343b2d4Sdrh} {one-c one-a two-b two-a three-c three-a}  ;# verify same order after sorting
2795343b2d4Sdrhdo_test 2.5c {
2805343b2d4Sdrh  db eval {
2815343b2d4Sdrh    EXPLAIN QUERY PLAN
282aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn DESC
2835343b2d4Sdrh  }
284aec93a1fSdrh} {/ORDER BY/}  ;# separate sorting pass due to mixed ASC/DESC
2855343b2d4Sdrh
2865343b2d4Sdrhdo_test 2.6a {
2875343b2d4Sdrh  db eval {
288aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY title DESC, tn DESC
2895343b2d4Sdrh  }
2905343b2d4Sdrh} {three-c three-a two-b two-a one-c one-a}
2915343b2d4Sdrhdo_test 2.6b {
2925343b2d4Sdrh  db eval {
293aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY +title DESC, +tn DESC
2945343b2d4Sdrh  }
2955343b2d4Sdrh} {three-c three-a two-b two-a one-c one-a}  ;# verify same order after sorting
2965343b2d4Sdrhdo_test 2.6c {
2975343b2d4Sdrh  db eval {
2985343b2d4Sdrh    EXPLAIN QUERY PLAN
299aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY title DESC, tn DESC
3005343b2d4Sdrh  }
301aec93a1fSdrh} {/ORDER BY/}  ;# ORDER BY required
3025343b2d4Sdrh
3035343b2d4Sdrh
3045343b2d4Sdrh# Generate another test dataset, but this time using mixed ASC/DESC indices.
3055343b2d4Sdrh#
3065343b2d4Sdrhdo_test 3.0 {
3075343b2d4Sdrh  db eval {
3085343b2d4Sdrh    BEGIN;
3095343b2d4Sdrh    DROP TABLE album;
3105343b2d4Sdrh    DROP TABLE track;
3115343b2d4Sdrh    CREATE TABLE album(
3125343b2d4Sdrh      aid INTEGER PRIMARY KEY,
3135343b2d4Sdrh      title TEXT UNIQUE NOT NULL
3145343b2d4Sdrh    );
3155343b2d4Sdrh    CREATE TABLE track(
3165343b2d4Sdrh      tid INTEGER PRIMARY KEY,
3175343b2d4Sdrh      aid INTEGER NOT NULL REFERENCES album,
3185343b2d4Sdrh      tn INTEGER NOT NULL,
3195343b2d4Sdrh      name TEXT,
3205343b2d4Sdrh      UNIQUE(aid ASC, tn DESC)
3215343b2d4Sdrh    );
3225343b2d4Sdrh    INSERT INTO album VALUES(1, '1-one'), (2, '2-two'), (3, '3-three');
3235343b2d4Sdrh    INSERT INTO track VALUES
3245343b2d4Sdrh        (NULL, 1, 1, 'one-a'),
3255343b2d4Sdrh        (NULL, 2, 2, 'two-b'),
3265343b2d4Sdrh        (NULL, 3, 3, 'three-c'),
3275343b2d4Sdrh        (NULL, 1, 3, 'one-c'),
3285343b2d4Sdrh        (NULL, 2, 1, 'two-a'),
3295343b2d4Sdrh        (NULL, 3, 1, 'three-a');
3305343b2d4Sdrh    COMMIT;
3315343b2d4Sdrh  }
3325343b2d4Sdrh} {}
3335343b2d4Sdrhdo_test 3.1a {
3345343b2d4Sdrh  db eval {
335782d68a4Sdrh    SELECT name FROM album CROSS JOIN track USING (aid) ORDER BY title, tn DESC
3365343b2d4Sdrh  }
3375343b2d4Sdrh} {one-c one-a two-b two-a three-c three-a}
3385343b2d4Sdrh
3395343b2d4Sdrh# Verify that the ORDER BY clause is optimized out
3405343b2d4Sdrh#
3415343b2d4Sdrhdo_test 3.1b {
3425343b2d4Sdrh  db eval {
3435343b2d4Sdrh    EXPLAIN QUERY PLAN
344782d68a4Sdrh    SELECT name FROM album CROSS JOIN track USING (aid) ORDER BY title, tn DESC
3455343b2d4Sdrh  }
3465343b2d4Sdrh} {~/ORDER BY/}  ;# ORDER BY optimized out
3475343b2d4Sdrh
3485343b2d4Sdrh# The same query with ORDER BY clause optimization disabled via + operators
3495343b2d4Sdrh# should give exactly the same answer.
3505343b2d4Sdrh#
3515343b2d4Sdrhdo_test 3.2a {
3525343b2d4Sdrh  db eval {
353aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY +title, +tn DESC
3545343b2d4Sdrh  }
3555343b2d4Sdrh} {one-c one-a two-b two-a three-c three-a}
3565343b2d4Sdrh
3575343b2d4Sdrh# The output is sorted manually in this case.
3585343b2d4Sdrh#
3595343b2d4Sdrhdo_test 3.2b {
3605343b2d4Sdrh  db eval {
3615343b2d4Sdrh    EXPLAIN QUERY PLAN
362aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY +title, +tn DESC
3635343b2d4Sdrh  }
3645343b2d4Sdrh} {/ORDER BY/}   ;# separate sorting pass due to "+" on ORDER BY terms
3655343b2d4Sdrh
3665343b2d4Sdrh# The same query with ORDER BY optimizations turned off via built-in test.
3675343b2d4Sdrh#
3685343b2d4Sdrhdo_test 3.3a {
3695343b2d4Sdrh  optimization_control db order-by-idx-join 0
3705343b2d4Sdrh  db cache flush
3715343b2d4Sdrh  db eval {
372aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn DESC
3735343b2d4Sdrh  }
3745343b2d4Sdrh} {one-c one-a two-b two-a three-c three-a}
3755343b2d4Sdrhdo_test 3.3b {
3765343b2d4Sdrh  db eval {
3775343b2d4Sdrh    EXPLAIN QUERY PLAN
378aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn DESC
3795343b2d4Sdrh  }
3805343b2d4Sdrh} {/ORDER BY/}   ;# separate sorting pass due to disabled optimization
3815343b2d4Sdrhoptimization_control db all 1
3825343b2d4Sdrhdb cache flush
3835343b2d4Sdrh
3845343b2d4Sdrh# Without the mixed ASC/DESC on ORDER BY
3855343b2d4Sdrh#
3865343b2d4Sdrhdo_test 3.4a {
3875343b2d4Sdrh  db eval {
388aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn
3895343b2d4Sdrh  }
3905343b2d4Sdrh} {one-a one-c two-a two-b three-a three-c}
3915343b2d4Sdrhdo_test 3.4b {
3925343b2d4Sdrh  db eval {
393aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY +title, +tn
3945343b2d4Sdrh  }
3955343b2d4Sdrh} {one-a one-c two-a two-b three-a three-c}  ;# verify same order after sorting
3965343b2d4Sdrhdo_test 3.4c {
3975343b2d4Sdrh  db eval {
3985343b2d4Sdrh    EXPLAIN QUERY PLAN
399aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY title, tn
4005343b2d4Sdrh  }
4014fe425adSdrh} {~/ORDER BY/}  ;# ORDER BY suppressed by uniqueness constraints
4025343b2d4Sdrh
4035343b2d4Sdrhdo_test 3.5a {
4045343b2d4Sdrh  db eval {
405aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY title DESC, tn DESC
4065343b2d4Sdrh  }
4075343b2d4Sdrh} {three-c three-a two-b two-a one-c one-a}
4085343b2d4Sdrhdo_test 3.5b {
4095343b2d4Sdrh  db eval {
410aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY +title DESC, +tn DESC
4115343b2d4Sdrh  }
4125343b2d4Sdrh} {three-c three-a two-b two-a one-c one-a}  ;# verify same order after sorting
4135343b2d4Sdrhdo_test 3.5c {
4145343b2d4Sdrh  db eval {
4155343b2d4Sdrh    EXPLAIN QUERY PLAN
416aec93a1fSdrh    SELECT name FROM album JOIN track USING (aid) ORDER BY title DESC, tn DESC
4175343b2d4Sdrh  }
4184fe425adSdrh} {~/ORDER BY/}  ;# ORDER BY suppressed by uniqueness constraints
4195343b2d4Sdrh
4205343b2d4Sdrh
4215343b2d4Sdrhdo_test 3.6a {
4225343b2d4Sdrh  db eval {
423782d68a4Sdrh    SELECT name FROM album CROSS JOIN track USING (aid) ORDER BY title DESC, tn
4245343b2d4Sdrh  }
4255343b2d4Sdrh} {three-a three-c two-a two-b one-a one-c}
4265343b2d4Sdrhdo_test 3.6b {
4275343b2d4Sdrh  db eval {
428aec93a1fSdrh    SELECT name FROM album CROSS JOIN track USING (aid)
429aec93a1fSdrh     ORDER BY +title DESC, +tn
4305343b2d4Sdrh  }
4315343b2d4Sdrh} {three-a three-c two-a two-b one-a one-c}  ;# verify same order after sorting
4325343b2d4Sdrhdo_test 3.6c {
4335343b2d4Sdrh  db eval {
4345343b2d4Sdrh    EXPLAIN QUERY PLAN
435782d68a4Sdrh    SELECT name FROM album CROSS JOIN track USING (aid) ORDER BY title DESC, tn
4365343b2d4Sdrh  }
4375343b2d4Sdrh} {~/ORDER BY/}  ;# inverted ASC/DESC is optimized out
4385343b2d4Sdrh
439aec93a1fSdrh# Ticket 5ed1772895bf3deeab78c5e3519b1da9165c541b (2013-06-04)
440aec93a1fSdrh# Incorrect ORDER BY on an indexed JOIN
441aec93a1fSdrh#
442aec93a1fSdrhdo_test 4.0 {
443aec93a1fSdrh  db eval {
444aec93a1fSdrh    CREATE TABLE t41(a INT UNIQUE NOT NULL, b INT NOT NULL);
445aec93a1fSdrh    CREATE INDEX t41ba ON t41(b,a);
446aec93a1fSdrh    CREATE TABLE t42(x INT NOT NULL REFERENCES t41(a), y INT NOT NULL);
447aec93a1fSdrh    CREATE UNIQUE INDEX t42xy ON t42(x,y);
448aec93a1fSdrh    INSERT INTO t41 VALUES(1,1),(3,1);
449aec93a1fSdrh    INSERT INTO t42 VALUES(1,13),(1,15),(3,14),(3,16);
450aec93a1fSdrh
451aec93a1fSdrh    SELECT b, y FROM t41 CROSS JOIN t42 ON x=a ORDER BY b, y;
452aec93a1fSdrh  }
453aec93a1fSdrh} {1 13 1 14 1 15 1 16}
454aec93a1fSdrh
4552504c6c6Sdrh# No sorting of queries that omit the FROM clause.
4562504c6c6Sdrh#
457fa16f5d9Sdrhdo_eqp_test 5.0 {
458fa16f5d9Sdrh  SELECT 5 ORDER BY 1
459fa16f5d9Sdrh} {
460fa16f5d9Sdrh  QUERY PLAN
461fa16f5d9Sdrh  `--SCAN CONSTANT ROW
462fa16f5d9Sdrh}
4632504c6c6Sdrhdo_execsql_test 5.1 {
4642504c6c6Sdrh  EXPLAIN QUERY PLAN SELECT 5 UNION ALL SELECT 3 ORDER BY 1
4652504c6c6Sdrh} {~/B-TREE/}
4662504c6c6Sdrhdo_execsql_test 5.2 {
4672504c6c6Sdrh  SELECT 5 UNION ALL SELECT 3 ORDER BY 1
4682504c6c6Sdrh} {3 5}
46911b04817Sdrhdo_execsql_test 5.3 {
47011b04817Sdrh  SELECT 986 AS x GROUP BY X ORDER BY X
47111b04817Sdrh} {986}
4725343b2d4Sdrh
473d0dc5d49Sdrh# The following test (originally derived from a single test within fuzz.test)
474d0dc5d49Sdrh# verifies that a PseudoTable cursor is not closed prematurely in a deeply
475d0dc5d49Sdrh# nested query.  This test caused a segfault on 3.8.5 beta.
476d0dc5d49Sdrh#
477d0dc5d49Sdrhdo_execsql_test 6.0 {
478d0dc5d49Sdrh  CREATE TABLE abc(a, b, c);
479d0dc5d49Sdrh  INSERT INTO abc VALUES(1, 2, 3);
480d0dc5d49Sdrh  INSERT INTO abc VALUES(4, 5, 6);
481d0dc5d49Sdrh  INSERT INTO abc VALUES(7, 8, 9);
482d0dc5d49Sdrh  SELECT (
483d0dc5d49Sdrh    SELECT 'hardware' FROM (
484d0dc5d49Sdrh      SELECT 'software' ORDER BY 'firmware' ASC, 'sportswear' DESC
485d0dc5d49Sdrh    ) GROUP BY 1 HAVING length(b)
486d0dc5d49Sdrh  )
487d0dc5d49Sdrh  FROM abc;
488d0dc5d49Sdrh} {hardware hardware hardware}
489d0dc5d49Sdrh
490137fd4fdSdrh# Here is a test for a query-planner problem reported on the SQLite
491137fd4fdSdrh# mailing list on 2014-09-18 by "Merike".  Beginning with version 3.8.0,
492137fd4fdSdrh# a separate sort was being used rather than using the single-column
493137fd4fdSdrh# index.  This was due to an oversight in the indexMightHelpWithOrderby()
494137fd4fdSdrh# routine in where.c.
495137fd4fdSdrh#
496137fd4fdSdrhdo_execsql_test 7.0 {
497137fd4fdSdrh  CREATE TABLE t7(a,b);
498137fd4fdSdrh  CREATE INDEX t7a ON t7(a);
499137fd4fdSdrh  CREATE INDEX t7ab ON t7(a,b);
500137fd4fdSdrh  EXPLAIN QUERY PLAN
501137fd4fdSdrh  SELECT * FROM t7 WHERE a=?1 ORDER BY rowid;
502137fd4fdSdrh} {~/ORDER BY/}
503137fd4fdSdrh
50496974bd3Sdan#-------------------------------------------------------------------------
50596974bd3Sdan# Test a partial sort large enough to cause the sorter to spill data
50696974bd3Sdan# to disk.
50796974bd3Sdan#
50896974bd3Sdanreset_db
50996974bd3Sdando_execsql_test 8.0 {
51096974bd3Sdan  PRAGMA cache_size = 5;
51196974bd3Sdan  CREATE TABLE t1(a, b);
51296974bd3Sdan  CREATE INDEX i1 ON t1(a);
51396974bd3Sdan}
51496974bd3Sdan
51596974bd3Sdando_eqp_test 8.1 {
51696974bd3Sdan  SELECT * FROM t1 ORDER BY a, b;
51796974bd3Sdan} {
518b3f0276bSdrh  QUERY PLAN
519*8210233cSdrh  |--SCAN t1 USING INDEX i1
520b3f0276bSdrh  `--USE TEMP B-TREE FOR RIGHT PART OF ORDER BY
52196974bd3Sdan}
52296974bd3Sdan
52396974bd3Sdando_execsql_test 8.2 {
52496974bd3Sdan  WITH cnt(i) AS (
52596974bd3Sdan    SELECT 1 UNION ALL SELECT i+1 FROM cnt WHERE i<10000
52696974bd3Sdan  )
52796974bd3Sdan  INSERT INTO t1 SELECT i%2, randomblob(500) FROM cnt;
52896974bd3Sdan}
52996974bd3Sdan
53096974bd3Sdando_test 8.3 {
53196974bd3Sdan  db eval { SELECT * FROM t1 ORDER BY a, b } { incr res $a }
53296974bd3Sdan  set res
53396974bd3Sdan} 5000
534d0dc5d49Sdrh
535a04a8be2Sdrh#---------------------------------------------------------------------------
536a04a8be2Sdrh# https://www.sqlite.org/src/tktview/cb3aa0641d9a413841c004293a4fc06cdc122029
537a04a8be2Sdrh#
538a04a8be2Sdrh# Adverse interaction between scalar subqueries and the partial-sorting
539a04a8be2Sdrh# logic.
540a04a8be2Sdrh#
541a04a8be2Sdrhdo_execsql_test 9.0 {
542a04a8be2Sdrh  DROP TABLE IF EXISTS t1;
543a04a8be2Sdrh  CREATE TABLE t1(x INTEGER PRIMARY KEY);
544a04a8be2Sdrh  INSERT INTO t1 VALUES(1),(2);
545a04a8be2Sdrh  DROP TABLE IF EXISTS t2;
546a04a8be2Sdrh  CREATE TABLE t2(y);
547a04a8be2Sdrh  INSERT INTO t2 VALUES(9),(8),(3),(4);
548a04a8be2Sdrh  SELECT (SELECT x||y FROM t2, t1 ORDER BY x, y);
549a04a8be2Sdrh} {13}
550a04a8be2Sdrh
551c6f36fa3Sdrh# Problem found by OSSFuzz on 2018-05-05.  This was caused by a new
552c6f36fa3Sdrh# optimization that had not been previously released.
553c6f36fa3Sdrh#
554c6f36fa3Sdrhdo_execsql_test 10.0 {
555c6f36fa3Sdrh  CREATE TABLE t10(a,b);
556c6f36fa3Sdrh  INSERT INTO t10 VALUES(1,2),(8,9),(3,4),(5,4),(0,7);
557c6f36fa3Sdrh  CREATE INDEX t10b ON t10(b);
558c6f36fa3Sdrh  SELECT b, rowid, '^' FROM t10 ORDER BY b, a LIMIT 4;
559c6f36fa3Sdrh} {2 1 ^ 4 3 ^ 4 4 ^ 7 5 ^}
560c6f36fa3Sdrh
561607dd6e6Sdando_catchsql_test 11.0 {
562607dd6e6Sdan  VALUES(2) EXCEPT SELECT '' ORDER BY abc
563607dd6e6Sdan} {1 {1st ORDER BY term does not match any column in the result set}}
564607dd6e6Sdan
565a04a8be2Sdrh
5666b10a6a7Sdrhfinish_test
567