提交 a8424521 authored 作者: Thomas Mueller's avatar Thomas Mueller

Nested UNION/INTERSECT queries with brackets could produce the wrong result if…

Nested UNION/INTERSECT queries with brackets could produce the wrong result if used within a subquery.
上级 3a086f29
...@@ -18,7 +18,9 @@ Change Log ...@@ -18,7 +18,9 @@ Change Log
<h1>Change Log</h1> <h1>Change Log</h1>
<h2>Next Version (unreleased)</h2> <h2>Next Version (unreleased)</h2>
<ul><li>Comparing an column against a constant expression with a higher precision or length <ul><li>Nested UNION/INTERSECT queries with brackets could produce the wrong result if used within a subquery. Example:
select count(*) from (select 1 union (select 2 intersect select 2)) x;
</li><li>Comparing an column against a constant expression with a higher precision or length
than the column could give wrong results (the expression was truncated before comparing). than the column could give wrong results (the expression was truncated before comparing).
</li><li>Improved PostgreSQL compatibility (support SHOW DEFAULT_TRANSACTION_ISOLATION). </li><li>Improved PostgreSQL compatibility (support SHOW DEFAULT_TRANSACTION_ISOLATION).
</li><li>Documentation: the javadocs for Csv.write and read used the wrong default charset. </li><li>Documentation: the javadocs for Csv.write and read used the wrong default charset.
......
...@@ -297,24 +297,24 @@ public class SelectUnion extends Query { ...@@ -297,24 +297,24 @@ public class SelectUnion extends Query {
public String getPlanSQL() { public String getPlanSQL() {
StringBuilder buff = new StringBuilder(); StringBuilder buff = new StringBuilder();
buff.append('(').append(StringUtils.unEnclose(left.getPlanSQL())).append(')'); buff.append('(').append(left.getPlanSQL()).append(')');
switch (unionType) { switch (unionType) {
case UNION_ALL: case UNION_ALL:
buff.append("UNION ALL "); buff.append(" UNION ALL ");
break; break;
case UNION: case UNION:
buff.append("UNION "); buff.append(" UNION ");
break; break;
case INTERSECT: case INTERSECT:
buff.append("INTERSECT "); buff.append(" INTERSECT ");
break; break;
case EXCEPT: case EXCEPT:
buff.append("EXCEPT "); buff.append(" EXCEPT ");
break; break;
default: default:
Message.throwInternalError("type=" + unionType); Message.throwInternalError("type=" + unionType);
} }
buff.append('(').append(StringUtils.unEnclose(right.getPlanSQL())).append(')'); buff.append('(').append(right.getPlanSQL()).append(')');
Expression[] exprList = expressions.toArray(new Expression[expressions.size()]); Expression[] exprList = expressions.toArray(new Expression[expressions.size()]);
if (sort != null) { if (sort != null) {
buff.append(" ORDER BY ").append(sort.getSQL(exprList, exprList.length)); buff.append(" ORDER BY ").append(sort.getSQL(exprList, exprList.length));
......
--- special grammar and test cases --------------------------------------------------------------------------------------------- --- special grammar and test cases ---------------------------------------------------------------------------------------------
select count(*) from (select 1 union (select 2 intersect select 2)) x;
> COUNT(*)
> --------
> 2
> rows: 1
create table test(id varchar(1) primary key) as select 'X'; create table test(id varchar(1) primary key) as select 'X';
> ok > ok
...@@ -5392,8 +5398,8 @@ SELECT * FROM (SELECT ID FROM TEST GROUP BY ID); ...@@ -5392,8 +5398,8 @@ SELECT * FROM (SELECT ID FROM TEST GROUP BY ID);
EXPLAIN SELECT * FROM TEST UNION ALL SELECT * FROM TEST ORDER BY ID LIMIT 2+0 OFFSET 1+0; EXPLAIN SELECT * FROM TEST UNION ALL SELECT * FROM TEST ORDER BY ID LIMIT 2+0 OFFSET 1+0;
> PLAN > PLAN
> ---------------------------------------------------------------------------------------------------------------------------------------------------------------------------- > -----------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> (SELECT TEST.ID, TEST.NAME FROM PUBLIC.TEST /* PUBLIC.TEST_DATA */)UNION ALL (SELECT TEST.ID, TEST.NAME FROM PUBLIC.TEST /* PUBLIC.TEST_DATA */) ORDER BY 1 LIMIT 2 OFFSET 1 > (SELECT TEST.ID, TEST.NAME FROM PUBLIC.TEST /* PUBLIC.TEST_DATA */) UNION ALL (SELECT TEST.ID, TEST.NAME FROM PUBLIC.TEST /* PUBLIC.TEST_DATA */) ORDER BY 1 LIMIT 2 OFFSET 1
> rows (ordered): 1 > rows (ordered): 1
EXPLAIN DELETE FROM TEST WHERE ID=1; EXPLAIN DELETE FROM TEST WHERE ID=1;
...@@ -5739,8 +5745,8 @@ SELECT * FROM SYSTEM_RANGE(1,2) UNION ALL SELECT * FROM SYSTEM_RANGE(1,2) ORDER ...@@ -5739,8 +5745,8 @@ SELECT * FROM SYSTEM_RANGE(1,2) UNION ALL SELECT * FROM SYSTEM_RANGE(1,2) ORDER
EXPLAIN (SELECT * FROM SYSTEM_RANGE(1,2) UNION ALL SELECT * FROM SYSTEM_RANGE(1,2) ORDER BY 1); EXPLAIN (SELECT * FROM SYSTEM_RANGE(1,2) UNION ALL SELECT * FROM SYSTEM_RANGE(1,2) ORDER BY 1);
> PLAN > PLAN
> --------------------------------------------------------------------------------------------------------------------------------------------------------------------- > ----------------------------------------------------------------------------------------------------------------------------------------------------------------------
> (SELECT SYSTEM_RANGE.X FROM SYSTEM_RANGE(1, 2) /* PUBLIC.RANGE_INDEX */)UNION ALL (SELECT SYSTEM_RANGE.X FROM SYSTEM_RANGE(1, 2) /* PUBLIC.RANGE_INDEX */) ORDER BY 1 > (SELECT SYSTEM_RANGE.X FROM SYSTEM_RANGE(1, 2) /* PUBLIC.RANGE_INDEX */) UNION ALL (SELECT SYSTEM_RANGE.X FROM SYSTEM_RANGE(1, 2) /* PUBLIC.RANGE_INDEX */) ORDER BY 1
> rows (ordered): 1 > rows (ordered): 1
CREATE TABLE CHILDREN(ID INT PRIMARY KEY, NAME VARCHAR(255), CLASS INT); CREATE TABLE CHILDREN(ID INT PRIMARY KEY, NAME VARCHAR(255), CLASS INT);
...@@ -5783,8 +5789,8 @@ SELECT * FROM CHILDREN UNION ALL SELECT * FROM CHILDREN ORDER BY ID, NAME FOR UP ...@@ -5783,8 +5789,8 @@ SELECT * FROM CHILDREN UNION ALL SELECT * FROM CHILDREN ORDER BY ID, NAME FOR UP
EXPLAIN SELECT * FROM CHILDREN UNION ALL SELECT * FROM CHILDREN ORDER BY ID, NAME FOR UPDATE; EXPLAIN SELECT * FROM CHILDREN UNION ALL SELECT * FROM CHILDREN ORDER BY ID, NAME FOR UPDATE;
> PLAN > PLAN
> --------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- > ----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> (SELECT CHILDREN.ID, CHILDREN.NAME, CHILDREN.CLASS FROM PUBLIC.CHILDREN /* PUBLIC.CHILDREN_DATA */ FOR UPDATE)UNION ALL (SELECT CHILDREN.ID, CHILDREN.NAME, CHILDREN.CLASS FROM PUBLIC.CHILDREN /* PUBLIC.CHILDREN_DATA */ FOR UPDATE) ORDER BY 1, 2 FOR UPDATE > (SELECT CHILDREN.ID, CHILDREN.NAME, CHILDREN.CLASS FROM PUBLIC.CHILDREN /* PUBLIC.CHILDREN_DATA */ FOR UPDATE) UNION ALL (SELECT CHILDREN.ID, CHILDREN.NAME, CHILDREN.CLASS FROM PUBLIC.CHILDREN /* PUBLIC.CHILDREN_DATA */ FOR UPDATE) ORDER BY 1, 2 FOR UPDATE
> rows (ordered): 1 > rows (ordered): 1
SELECT 'Child', ID, NAME FROM CHILDREN UNION SELECT 'Class', ID, NAME FROM CLASSES; SELECT 'Child', ID, NAME FROM CHILDREN UNION SELECT 'Class', ID, NAME FROM CLASSES;
...@@ -5803,8 +5809,8 @@ SELECT 'Child', ID, NAME FROM CHILDREN UNION SELECT 'Class', ID, NAME FROM CLASS ...@@ -5803,8 +5809,8 @@ SELECT 'Child', ID, NAME FROM CHILDREN UNION SELECT 'Class', ID, NAME FROM CLASS
EXPLAIN SELECT 'Child', ID, NAME FROM CHILDREN UNION SELECT 'Class', ID, NAME FROM CLASSES; EXPLAIN SELECT 'Child', ID, NAME FROM CHILDREN UNION SELECT 'Class', ID, NAME FROM CLASSES;
> PLAN > PLAN
> -------------------------------------------------------------------------------------------------------------------------------------------------------- > ---------------------------------------------------------------------------------------------------------------------------------------------------------
> (SELECT 'Child', ID, NAME FROM PUBLIC.CHILDREN /* PUBLIC.CHILDREN_DATA */)UNION (SELECT 'Class', ID, NAME FROM PUBLIC.CLASSES /* PUBLIC.CLASSES_DATA */) > (SELECT 'Child', ID, NAME FROM PUBLIC.CHILDREN /* PUBLIC.CHILDREN_DATA */) UNION (SELECT 'Class', ID, NAME FROM PUBLIC.CLASSES /* PUBLIC.CLASSES_DATA */)
> rows: 1 > rows: 1
SELECT * FROM CHILDREN EXCEPT SELECT * FROM CHILDREN WHERE CLASS=0; SELECT * FROM CHILDREN EXCEPT SELECT * FROM CHILDREN WHERE CLASS=0;
...@@ -5817,14 +5823,14 @@ SELECT * FROM CHILDREN EXCEPT SELECT * FROM CHILDREN WHERE CLASS=0; ...@@ -5817,14 +5823,14 @@ SELECT * FROM CHILDREN EXCEPT SELECT * FROM CHILDREN WHERE CLASS=0;
EXPLAIN SELECT * FROM CHILDREN EXCEPT SELECT * FROM CHILDREN WHERE CLASS=0; EXPLAIN SELECT * FROM CHILDREN EXCEPT SELECT * FROM CHILDREN WHERE CLASS=0;
> PLAN > PLAN
> ----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- > ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> (SELECT CHILDREN.ID, CHILDREN.NAME, CHILDREN.CLASS FROM PUBLIC.CHILDREN /* PUBLIC.CHILDREN_DATA */)EXCEPT (SELECT CHILDREN.ID, CHILDREN.NAME, CHILDREN.CLASS FROM PUBLIC.CHILDREN /* PUBLIC.CHILDREN_DATA */ WHERE CLASS = 0) > (SELECT CHILDREN.ID, CHILDREN.NAME, CHILDREN.CLASS FROM PUBLIC.CHILDREN /* PUBLIC.CHILDREN_DATA */) EXCEPT (SELECT CHILDREN.ID, CHILDREN.NAME, CHILDREN.CLASS FROM PUBLIC.CHILDREN /* PUBLIC.CHILDREN_DATA */ WHERE CLASS = 0)
> rows: 1 > rows: 1
EXPLAIN SELECT CLASS FROM CHILDREN INTERSECT SELECT ID FROM CLASSES; EXPLAIN SELECT CLASS FROM CHILDREN INTERSECT SELECT ID FROM CLASSES;
> PLAN > PLAN
> --------------------------------------------------------------------------------------------------------------------------------- > ----------------------------------------------------------------------------------------------------------------------------------
> (SELECT CLASS FROM PUBLIC.CHILDREN /* PUBLIC.CHILDREN_DATA */)INTERSECT (SELECT ID FROM PUBLIC.CLASSES /* PUBLIC.CLASSES_DATA */) > (SELECT CLASS FROM PUBLIC.CHILDREN /* PUBLIC.CHILDREN_DATA */) INTERSECT (SELECT ID FROM PUBLIC.CLASSES /* PUBLIC.CLASSES_DATA */)
> rows: 1 > rows: 1
SELECT CLASS FROM CHILDREN INTERSECT SELECT ID FROM CLASSES; SELECT CLASS FROM CHILDREN INTERSECT SELECT ID FROM CLASSES;
...@@ -5837,8 +5843,8 @@ SELECT CLASS FROM CHILDREN INTERSECT SELECT ID FROM CLASSES; ...@@ -5837,8 +5843,8 @@ SELECT CLASS FROM CHILDREN INTERSECT SELECT ID FROM CLASSES;
EXPLAIN SELECT * FROM CHILDREN EXCEPT SELECT * FROM CHILDREN WHERE CLASS=0; EXPLAIN SELECT * FROM CHILDREN EXCEPT SELECT * FROM CHILDREN WHERE CLASS=0;
> PLAN > PLAN
> ----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- > ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> (SELECT CHILDREN.ID, CHILDREN.NAME, CHILDREN.CLASS FROM PUBLIC.CHILDREN /* PUBLIC.CHILDREN_DATA */)EXCEPT (SELECT CHILDREN.ID, CHILDREN.NAME, CHILDREN.CLASS FROM PUBLIC.CHILDREN /* PUBLIC.CHILDREN_DATA */ WHERE CLASS = 0) > (SELECT CHILDREN.ID, CHILDREN.NAME, CHILDREN.CLASS FROM PUBLIC.CHILDREN /* PUBLIC.CHILDREN_DATA */) EXCEPT (SELECT CHILDREN.ID, CHILDREN.NAME, CHILDREN.CLASS FROM PUBLIC.CHILDREN /* PUBLIC.CHILDREN_DATA */ WHERE CLASS = 0)
> rows: 1 > rows: 1
SELECT * FROM CHILDREN CH, CLASSES CL WHERE CH.CLASS = CL.ID; SELECT * FROM CHILDREN CH, CLASSES CL WHERE CH.CLASS = CL.ID;
...@@ -5928,8 +5934,8 @@ SELECT * FROM V_UNION WHERE ID=1; ...@@ -5928,8 +5934,8 @@ SELECT * FROM V_UNION WHERE ID=1;
EXPLAIN SELECT * FROM V_UNION WHERE ID=1; EXPLAIN SELECT * FROM V_UNION WHERE ID=1;
> PLAN > PLAN
> ---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- > -----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT V_UNION.ID, V_UNION.NAME, V_UNION.CLASS FROM PUBLIC.V_UNION /* (SELECT CHILDREN.ID, CHILDREN.NAME, CHILDREN.CLASS FROM PUBLIC.CHILDREN /++ PUBLIC.PRIMARY_KEY_9: ID = ?1 ++/ WHERE CHILDREN.ID = ?1)UNION ALL (SELECT CHILDREN.ID, CHILDREN.NAME, CHILDREN.CLASS FROM PUBLIC.CHILDREN /++ PUBLIC.PRIMARY_KEY_9: ID = ?1 ++/ WHERE CHILDREN.ID = ?1): ID = 1 */ WHERE ID = 1 > SELECT V_UNION.ID, V_UNION.NAME, V_UNION.CLASS FROM PUBLIC.V_UNION /* (SELECT CHILDREN.ID, CHILDREN.NAME, CHILDREN.CLASS FROM PUBLIC.CHILDREN /++ PUBLIC.PRIMARY_KEY_9: ID = ?1 ++/ WHERE CHILDREN.ID = ?1) UNION ALL (SELECT CHILDREN.ID, CHILDREN.NAME, CHILDREN.CLASS FROM PUBLIC.CHILDREN /++ PUBLIC.PRIMARY_KEY_9: ID = ?1 ++/ WHERE CHILDREN.ID = ?1): ID = 1 */ WHERE ID = 1
> rows: 1 > rows: 1
CREATE VIEW V_EXCEPT AS SELECT * FROM CHILDREN EXCEPT SELECT * FROM CHILDREN WHERE ID=2; CREATE VIEW V_EXCEPT AS SELECT * FROM CHILDREN EXCEPT SELECT * FROM CHILDREN WHERE ID=2;
...@@ -5943,8 +5949,8 @@ SELECT * FROM V_EXCEPT WHERE ID=1; ...@@ -5943,8 +5949,8 @@ SELECT * FROM V_EXCEPT WHERE ID=1;
EXPLAIN SELECT * FROM V_EXCEPT WHERE ID=1; EXPLAIN SELECT * FROM V_EXCEPT WHERE ID=1;
> PLAN > PLAN
> ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------ > -------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT V_EXCEPT.ID, V_EXCEPT.NAME, V_EXCEPT.CLASS FROM PUBLIC.V_EXCEPT /* (SELECT CHILDREN.ID, CHILDREN.NAME, CHILDREN.CLASS FROM PUBLIC.CHILDREN /++ PUBLIC.PRIMARY_KEY_9: ID = ?1 ++/ WHERE CHILDREN.ID = ?1)EXCEPT (SELECT CHILDREN.ID, CHILDREN.NAME, CHILDREN.CLASS FROM PUBLIC.CHILDREN /++ PUBLIC.PRIMARY_KEY_9: ID = 2 ++/ WHERE ID = 2): ID = 1 */ WHERE ID = 1 > SELECT V_EXCEPT.ID, V_EXCEPT.NAME, V_EXCEPT.CLASS FROM PUBLIC.V_EXCEPT /* (SELECT CHILDREN.ID, CHILDREN.NAME, CHILDREN.CLASS FROM PUBLIC.CHILDREN /++ PUBLIC.PRIMARY_KEY_9: ID = ?1 ++/ WHERE CHILDREN.ID = ?1) EXCEPT (SELECT CHILDREN.ID, CHILDREN.NAME, CHILDREN.CLASS FROM PUBLIC.CHILDREN /++ PUBLIC.PRIMARY_KEY_9: ID = 2 ++/ WHERE ID = 2): ID = 1 */ WHERE ID = 1
> rows: 1 > rows: 1
CREATE VIEW V_INTERSECT AS SELECT ID, NAME FROM CHILDREN INTERSECT SELECT * FROM CLASSES; CREATE VIEW V_INTERSECT AS SELECT ID, NAME FROM CHILDREN INTERSECT SELECT * FROM CLASSES;
...@@ -5957,8 +5963,8 @@ SELECT * FROM V_INTERSECT WHERE ID=1; ...@@ -5957,8 +5963,8 @@ SELECT * FROM V_INTERSECT WHERE ID=1;
EXPLAIN SELECT * FROM V_INTERSECT WHERE ID=1; EXPLAIN SELECT * FROM V_INTERSECT WHERE ID=1;
> PLAN > PLAN
> ---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- > -----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT V_INTERSECT.ID, V_INTERSECT.NAME FROM PUBLIC.V_INTERSECT /* (SELECT ID, NAME FROM PUBLIC.CHILDREN /++ PUBLIC.PRIMARY_KEY_9: ID = ?1 ++/ WHERE ID = ?1)INTERSECT (SELECT CLASSES.ID, CLASSES.NAME FROM PUBLIC.CLASSES /++ PUBLIC.PRIMARY_KEY_5: ID = ?1 ++/ WHERE CLASSES.ID = ?1): ID = 1 */ WHERE ID = 1 > SELECT V_INTERSECT.ID, V_INTERSECT.NAME FROM PUBLIC.V_INTERSECT /* (SELECT ID, NAME FROM PUBLIC.CHILDREN /++ PUBLIC.PRIMARY_KEY_9: ID = ?1 ++/ WHERE ID = ?1) INTERSECT (SELECT CLASSES.ID, CLASSES.NAME FROM PUBLIC.CLASSES /++ PUBLIC.PRIMARY_KEY_5: ID = ?1 ++/ WHERE CLASSES.ID = ?1): ID = 1 */ WHERE ID = 1
> rows: 1 > rows: 1
DROP VIEW V_UNION; DROP VIEW V_UNION;
......
Markdown 格式
0%
您添加了 0 到此讨论。请谨慎行事。
请先完成此评论的编辑!
注册 或者 后发表评论