Disable the query flattening optimization when the subquery is a compound

query with an ORDER BY clause.  Ticket #3773 shows why that combination
does not work. (CVS 6437)

FossilOrigin-Name: 23f90d50737a36ebd17152dd4667948ce7049967
This commit is contained in:
drh 2009-04-02 16:59:47 +00:00
parent 3034e3d364
commit e8902a70fe
5 changed files with 88 additions and 38 deletions

View File

@ -1,5 +1,5 @@
C Change\sthe\sway\sthat\sthe\srandom()\sSQL\sfunction\sprevents\sthe\smaximum\nnegative\sinteger\sso\sthat\sit\sis\stestable.\s(CVS\s6436)
D 2009-04-02T14:05:22
C Disable\sthe\squery\sflattening\soptimization\swhen\sthe\ssubquery\sis\sa\scompound\nquery\swith\san\sORDER\sBY\sclause.\s\sTicket\s#3773\sshows\swhy\sthat\scombination\ndoes\snot\swork.\s(CVS\s6437)
D 2009-04-02T16:59:47
F Makefile.arm-wince-mingw32ce-gcc fcd5e9cd67fe88836360bb4f9ef4cb7f8e2fb5a0
F Makefile.in 583e87706abc3026960ed759aff6371faf84c211
F Makefile.linux-gcc d53183f4aa6a9192d249731c90dbdffbd2c68654
@ -155,7 +155,7 @@ F src/printf.c 9866a9a9c4a90f6d4147407f373df3fd5d5f9b6f
F src/random.c 676b9d7ac820fe81e6fb2394ac8c10cff7f38628
F src/resolve.c 094e44450371fb27869eb8bf679aacbe51fdc56d
F src/rowset.c badb9f36b3a2ced9ee9551f4ce730f5fab442791
F src/select.c bd494b68a54a51de3df94ecdd6d24fa7598929d1
F src/select.c 462d9671e91accd983110fa38674be0d2a3daa66
F src/shell.c 0a11f831603f17fea20ca97133c0f64e716af4a7
F src/sqlite.h.in 0db1e59d89aeacb8fe64a19fd14c13a796060ccb
F src/sqlite3ext.h 1db7d63ab5de4b3e6b83dd03d1a4e64fef6d2a17
@ -525,7 +525,7 @@ F test/select7.test 7906735805cfbee4dddc0bed4c14e68d7f5f9c5f
F test/select8.test 391de11bdd52339c30580dabbbbe97e3e9a3c79d
F test/select9.test b4007b15396cb7ba2615cab31e1973b572e43210
F test/selectA.test 06d1032fa9009314c95394f2ca2e60d9f7ae8532
F test/selectB.test 31e81ac9af7d224850e0706350f070ecb92fcbc7
F test/selectB.test f305cc6660804cb239aab4e2f26b0e288b59958b
F test/selectC.test ae49d258c875bc1712898f1632062bc5c01a7470
F test/server1.test f5b790d4c0498179151ca8a7715a65a7802c859c
F test/shared.test 3b448dc0f7a9356e641894ed81c27599f39d809d
@ -635,6 +635,7 @@ F test/tkt3731.test 8a6e3732f5a8a24eb875a6faf287ef77bb8c0579
F test/tkt3757.test 8f2208930655bbd4f92c14e19e72303a43e098ef
F test/tkt3761.test b95ea9c98f21cf91325f18a984887e62caceab33
F test/tkt3762.test 2a9f3b03df44ec49ec0cfa8d5da6574c2a7853df
F test/tkt3773.test 430b06567ce40285dfd2c4834a2a61816403efeb
F test/tokenize.test ce430a7aed48fc98301611429595883fdfcab5d7
F test/trace.test 951cd0f5f571e7f36bf7bfe04be70f90fb16fb00
F test/trans.test 8b79967a7e085289ec64890c6fdf9d089e1b4a5f
@ -714,7 +715,7 @@ F tool/speedtest16.c c8a9c793df96db7e4933f0852abb7a03d48f2e81
F tool/speedtest2.tcl ee2149167303ba8e95af97873c575c3e0fab58ff
F tool/speedtest8.c 2902c46588c40b55661e471d7a86e4dd71a18224
F tool/speedtest8inst1.c 293327bc76823f473684d589a8160bde1f52c14e
P eb65e64e7ed5edbe506365971d4d81ea037098d3
R 8df4d225606e2ef05ef65f87475b71e8
P 995f2b9b1031fadc85e179701536b9dd4153654b
R 46fe8bc037aad00af46b1a5a3fe7667b
U drh
Z 5cdbeb238444c4b2ca5bad90a2a75082
Z e4c9dcb4224dad890dcbd3f746876a28

View File

@ -1 +1 @@
995f2b9b1031fadc85e179701536b9dd4153654b
23f90d50737a36ebd17152dd4667948ce7049967

View File

@ -12,7 +12,7 @@
** This file contains C code routines that are called by the parser
** to handle SELECT statements in SQLite.
**
** $Id: select.c,v 1.506 2009/03/31 03:41:57 shane Exp $
** $Id: select.c,v 1.507 2009/04/02 16:59:47 drh Exp $
*/
#include "sqliteInt.h"
@ -2555,6 +2555,12 @@ static void substSelect(
** (19) The subquery does not use LIMIT or the outer query does not
** have a WHERE clause.
**
** (20) If the sub-query is a compound select, then it must not use
** an ORDER BY clause. Ticket #3773. We could relax this constraint
** somewhat by saying that the terms of the ORDER BY clause must
** appear as unmodified result columns in the outer query. But
** have other optimizations in mind to deal with that case.
**
** In this routine, the "p" parameter is a pointer to the outer query.
** The subquery is p->pSrc->a[iFrom]. isAgg is true if the outer query
** uses aggregates and subqueryIsAgg is true if the subquery uses aggregates.
@ -2665,6 +2671,9 @@ static int flattenSubquery(
** queries.
*/
if( pSub->pPrior ){
if( pSub->pOrderBy ){
return 0; /* Restriction 20 */
}
if( isAgg || (p->selFlags & SF_Distinct)!=0 || pSrc->nSrc!=1 ){
return 0;
}

View File

@ -10,7 +10,7 @@
#***********************************************************************
# This file implements regression tests for SQLite library.
#
# $Id: selectB.test,v 1.9 2008/08/04 03:51:24 danielk1977 Exp $
# $Id: selectB.test,v 1.10 2009/04/02 16:59:47 drh Exp $
set testdir [file dirname $argv0]
source $testdir/tester.tcl
@ -122,7 +122,7 @@ for {set ii 1} {$ii <= 2} {incr ii} {
} {
SELECT a FROM t1 UNION ALL SELECT d FROM t2 ORDER BY 1 LIMIT 2 OFFSET 3
} {12 14}
test_transform selectB-$ii.9 {
SELECT * FROM (
SELECT a FROM t1 UNION ALL SELECT d FROM t2 UNION ALL SELECT c FROM t1
@ -156,33 +156,35 @@ for {set ii 1} {$ii <= 2} {incr ii} {
SELECT a FROM t1 UNION ALL SELECT d FROM t2 LIMIT 2
} {2 8}
test_transform selectB-$ii.13 {
SELECT * FROM (SELECT a FROM t1 UNION ALL SELECT d FROM t2 ORDER BY a ASC)
} {
SELECT a FROM t1 UNION ALL SELECT d FROM t2 ORDER BY 1 ASC
} {2 3 8 12 14 21}
test_transform selectB-$ii.14 {
SELECT * FROM (SELECT a FROM t1 UNION ALL SELECT d FROM t2 ORDER BY a DESC)
} {
SELECT a FROM t1 UNION ALL SELECT d FROM t2 ORDER BY 1 DESC
} {21 14 12 8 3 2}
test_transform selectB-$ii.14 {
SELECT * FROM (
SELECT a FROM t1 UNION ALL SELECT d FROM t2 ORDER BY a DESC
) LIMIT 2 OFFSET 2
} {
SELECT a FROM t1 UNION ALL SELECT d FROM t2 ORDER BY 1 DESC LIMIT 2 OFFSET 2
} {12 8}
test_transform selectB-$ii.15 {
SELECT * FROM (
SELECT a, b FROM t1 UNION ALL SELECT d, e FROM t2 ORDER BY a ASC, e DESC
)
} {
SELECT a, b FROM t1 UNION ALL SELECT d, e FROM t2 ORDER BY a ASC, e DESC
} {2 4 3 6 8 10 12 15 14 16 21 24}
# An ORDER BY in a compound subqueries defeats flattening. Ticket #3773
# test_transform selectB-$ii.13 {
# SELECT * FROM (SELECT a FROM t1 UNION ALL SELECT d FROM t2 ORDER BY a ASC)
# } {
# SELECT a FROM t1 UNION ALL SELECT d FROM t2 ORDER BY 1 ASC
# } {2 3 8 12 14 21}
#
# test_transform selectB-$ii.14 {
# SELECT * FROM (SELECT a FROM t1 UNION ALL SELECT d FROM t2 ORDER BY a DESC)
# } {
# SELECT a FROM t1 UNION ALL SELECT d FROM t2 ORDER BY 1 DESC
# } {21 14 12 8 3 2}
#
# test_transform selectB-$ii.14 {
# SELECT * FROM (
# SELECT a FROM t1 UNION ALL SELECT d FROM t2 ORDER BY a DESC
# ) LIMIT 2 OFFSET 2
# } {
# SELECT a FROM t1 UNION ALL SELECT d FROM t2 ORDER BY 1 DESC
# LIMIT 2 OFFSET 2
# } {12 8}
#
# test_transform selectB-$ii.15 {
# SELECT * FROM (
# SELECT a, b FROM t1 UNION ALL SELECT d, e FROM t2 ORDER BY a ASC, e DESC
# )
# } {
# SELECT a, b FROM t1 UNION ALL SELECT d, e FROM t2 ORDER BY a ASC, e DESC
# } {2 4 3 6 8 10 12 15 14 16 21 24}
}
do_test selectB-3.0 {

38
test/tkt3773.test Normal file
View File

@ -0,0 +1,38 @@
# 2009 April 2
#
# 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.
#
#***********************************************************************
#
# Ticket #3773: Be careful not to over-optimize when a compound
# subquery contains an ORDER BY clause.
#
#
# $Id: tkt3773.test,v 1.1 2009/04/02 16:59:47 drh Exp $
set testdir [file dirname $argv0]
source $testdir/tester.tcl
do_test tkt3773-1.1 {
db eval {
CREATE TABLE t1(a,b);
INSERT INTO t1 VALUES(2,1);
INSERT INTO t1 VALUES(33,3);
CREATE TABLE t2(x,y);
INSERT INTO t2 VALUES(123,2);
INSERT INTO t2 VALUES(4,4);
SELECT a FROM (
SELECT a, b FROM t1
UNION ALL
SELECT x, y FROM t2
ORDER BY 2
);
}
} {2 123 33 4}
finish_test