From 3fc673e622148f787a8c2188c2c2d2fbcacd2a05 Mon Sep 17 00:00:00 2001 From: drh Date: Mon, 16 Jun 2003 00:40:34 +0000 Subject: [PATCH] Do not flatten a subquery which is the right term of a LEFT OUTER JOIN if the subquery contains a WHERE clause. Ticket #350. (CVS 1027) FossilOrigin-Name: dd8943e8583cf7ed3b662570a5607856fd246dac --- manifest | 14 +++++++------- manifest.uuid | 2 +- src/select.c | 23 ++++++++++++++++++++++- test/join.test | 41 ++++++++++++++++++++++++++++++++++++++++- 4 files changed, 70 insertions(+), 10 deletions(-) diff --git a/manifest b/manifest index 8fae0c5ab0..ea68d42073 100644 --- a/manifest +++ b/manifest @@ -1,5 +1,5 @@ -C Preserve\sblank\slines\sin\sthe\smiddle\sof\sSQL\sstatements\sin\sthe\sshell.\nTicket\s#352\s(CVS\s1026) -D 2003-06-16T00:16:41 +C Do\snot\sflatten\sa\ssubquery\swhich\sis\sthe\sright\sterm\sof\sa\sLEFT\sOUTER\sJOIN\nif\sthe\ssubquery\scontains\sa\sWHERE\sclause.\s\sTicket\s#350.\s(CVS\s1027) +D 2003-06-16T00:40:35 F Makefile.in 9ad23ed4ca97f9670c4496432e3fbd4b3760ebde F Makefile.linux-gcc b86a99c493a5bfb402d1d9178dcdc4bd4b32f906 F README f1de682fbbd94899d50aca13d387d1b3fd3be2dd @@ -43,7 +43,7 @@ F src/parse.y 917250e5d86bdee752355e6617ea2e8ee12438bf F src/pragma.c 3b4f5a800e7a2145bc1930f323232e297d4eb782 F src/printf.c 12ab57e638c8201033c96717df7af59e06933314 F src/random.c 19e8e00fe0df32a742f115773f57651be327cabe -F src/select.c 76b3a5cda76421cfe82d6a96c72308c2518cb2f9 +F src/select.c 29c53228a4e66bfcebd797b7539678fcd0e2cf64 F src/shell.c 3ed268908fd69c8fd4b28dbe415075cbf0e3991a F src/shell.tcl 27ecbd63dd88396ad16d81ab44f73e6c0ea9d20e F src/sqlite.h.in 54619fa5df4c83b22def66bb3d24808fd03dcbae @@ -87,7 +87,7 @@ F test/insert.test a17b7f7017097afb2727aa5b67ceeb7ab0a120a1 F test/insert2.test c288375a64dad3295044714f0dfed4a193cf067f F test/intpkey.test 9320af48415c594afd4e15f8ef0daa272e05502e F test/ioerr.test 5dbaf09f96b56ee01cf3edd762b96eb4ad2c9ca4 -F test/join.test 16c91ec27170c20e2a10796775e62c5c3dcbda44 +F test/join.test 54e770b74fc8cfc7769d5d0bb05657085641b3c4 F test/limit.test 9ffb965a0f5bf7152187ef3d8d1249b96e5620bf F test/lock.test 388a3a10962d2d571c0c1821cc35bf069ee73473 F test/main.test 6a851b5992c4881a725a3d9647e629199df8de9d @@ -165,7 +165,7 @@ F www/speed.tcl 296cc5632d069b56d3ef5409ca0df90f486c10fb F www/sqlite.tcl 4bd1729e320f5fa9125f0022b281fbe839192125 F www/tclsqlite.tcl 1db15abeb446aad0caf0b95b8b9579720e4ea331 F www/vdbe.tcl 14fdcc7fe8a60a6ba8584903636db8dc37eef26a -P 38461a7acb5281edd7078b1b3f227bb45f281757 -R 46499a749b6ee84c69c37552983b6d8c +P bcf5eeecdfd9897bc7c257119d7515fd34d222c1 +R ffe0cc5608b1ae6c3500625d1dc9cf93 U drh -Z b3ef2420e7aa106912624a6b067565c3 +Z d81db5180d17921ff4a8ae510148f465 diff --git a/manifest.uuid b/manifest.uuid index f94643bb3d..17938aa296 100644 --- a/manifest.uuid +++ b/manifest.uuid @@ -1 +1 @@ -bcf5eeecdfd9897bc7c257119d7515fd34d222c1 \ No newline at end of file +dd8943e8583cf7ed3b662570a5607856fd246dac \ No newline at end of file diff --git a/src/select.c b/src/select.c index 1b6d45ef7e..5b0d375695 100644 --- a/src/select.c +++ b/src/select.c @@ -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.140 2003/05/31 16:21:13 drh Exp $ +** $Id: select.c,v 1.141 2003/06/16 00:40:35 drh Exp $ */ #include "sqliteInt.h" @@ -1578,6 +1578,9 @@ substExprList(ExprList *pList, int iTable, ExprList *pEList){ ** ** (11) The subquery and the outer query do not both have ORDER BY clauses. ** +** (12) The subquery is not the right term of a LEFT OUTER JOIN or the +** subquery has no WHERE clause. (added by ticket #350) +** ** 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. @@ -1637,6 +1640,24 @@ static int flattenSubquery( return 0; } + /* Restriction 12: If the subquery is the right operand of a left outer + ** join, make sure the subquery has no WHERE clause. + ** An examples of why this is not allowed: + ** + ** t1 LEFT OUTER JOIN (SELECT * FROM t2 WHERE t2.x>0) + ** + ** If we flatten the above, we would get + ** + ** (t1 LEFT OUTER JOIN t2) WHERE t2.x>0 + ** + ** But the t2.x>0 test will always fail on a NULL row of t2, which + ** effectively converts the OUTER JOIN into an INNER JOIN. + */ + if( iFrom>0 && (pSrc->a[iFrom-1].jointype & JT_OUTER)!=0 + && pSub->pWhere!=0 ){ + return 0; + } + /* If we reach this point, it means flattening is permitted for the ** iFrom-th entry of the FROM clause in the outer query. */ diff --git a/test/join.test b/test/join.test index 1d62845cb4..c7b4835f46 100644 --- a/test/join.test +++ b/test/join.test @@ -12,7 +12,7 @@ # # This file implements tests for joins, including outer joins. # -# $Id: join.test,v 1.9 2003/05/06 20:35:17 drh Exp $ +# $Id: join.test,v 1.10 2003/06/16 00:40:35 drh Exp $ set testdir [file dirname $argv0] source $testdir/tester.tcl @@ -398,9 +398,48 @@ do_test join-8.1 { } } {1 11 1 111 2 22 {} {}} do_test join-8.2 { + execsql { + SELECT * FROM t9 LEFT JOIN (SELECT x, q FROM t10, t11 WHERE t10.y=t11.p) + ON( a=x); + } +} {1 11 1 111 2 22 {} {}} +do_test join-8.3 { execsql { SELECT * FROM v10_11 LEFT JOIN t9 ON( a=x ); } } {1 111 1 11 3 333 {} {}} +# Ticket #350 describes a scenario where LEFT OUTER JOIN does not +# function correctly if the right table in the join is really +# subquery. +# +# To test the problem, we generate the same LEFT OUTER JOIN in two +# separate selects but with on using a subquery and the other calling +# the table directly. Then connect the two SELECTs using an EXCEPT. +# Both queries should generate the same results so the answer should +# be an empty set. +# +do_test join-9.1 { + execsql { + BEGIN; + CREATE TABLE t12(a,b); + INSERT INTO t12 VALUES(1,11); + INSERT INTO t12 VALUES(2,22); + CREATE TABLE t13(b,c); + INSERT INTO t13 VALUES(22,222); + COMMIT; + SELECT * FROM t12 NATURAL LEFT JOIN t13 + EXCEPT + SELECT * FROM t12 NATURAL LEFT JOIN (SELECT * FROM t13 WHERE b>0); + } +} {} +do_test join-9.2 { + execsql { + CREATE VIEW v13 AS SELECT * FROM t13 WHERE b>0; + SELECT * FROM t12 NATURAL LEFT JOIN t13 + EXCEPT + SELECT * FROM t12 NATURAL LEFT JOIN v13; + } +} {} + finish_test