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

Natural join: the joined columns are not repeated any more when using SELECT *.

上级 3de090e0
......@@ -1252,8 +1252,10 @@ public class Parser {
for (int t = 0; t < tableCols.length; t++) {
String tableColumnName = tableCols[t].getName();
for (int j = 0; j < joinCols.length; j++) {
String joinColumnName = joinCols[j].getName();
Column c = joinCols[j];
String joinColumnName = c.getName();
if (tableColumnName.equals(joinColumnName)) {
join.addNaturalJoinColumn(c);
Expression tableExpr = new ExpressionColumn(database, tableSchema, last
.getTableAlias(), tableColumnName);
Expression joinExpr = new ExpressionColumn(database, joinSchema, join
......
......@@ -608,6 +608,9 @@ public class Select extends Query {
Column[] columns = t.getColumns();
for (int j = 0; j < columns.length; j++) {
Column c = columns[j];
if (filter.isNaturalJoinColumn(c)) {
continue;
}
ExpressionColumn ec = new ExpressionColumn(session.getDatabase(), null, alias, c.getName());
expressions.add(i++, ec);
}
......
......@@ -64,6 +64,7 @@ public class TableFilter implements ColumnResolver {
private TableFilter join;
private boolean outerJoin;
private ObjectArray naturalJoinColumns;
private boolean foundOne;
private Expression fullCondition;
......@@ -726,4 +727,26 @@ public class TableFilter implements ColumnResolver {
return alias != null ? alias : "" + table;
}
/**
* Add a column to the natural join key column list.
*
* @param c the column to add
*/
public void addNaturalJoinColumn(Column c) {
if (naturalJoinColumns == null) {
naturalJoinColumns = new ObjectArray();
}
naturalJoinColumns.add(c);
}
/**
* Check if the given column is a natural join column.
*
* @param c the column to check
* @return true if this is a joined natural join column
*/
public boolean isNaturalJoinColumn(Column c) {
return naturalJoinColumns != null && naturalJoinColumns.indexOf(c) >= 0;
}
}
......@@ -2706,9 +2706,9 @@ select * from two;
select * from one natural join two left join two three on
one.id=three.id left join one four on two.id=four.id where three.val
is null;
> ID ID VAL ID VAL ID
> -- -- ---- -- ---- --
> 0 0 null 0 null 0
> ID VAL ID VAL ID
> -- ---- -- ---- --
> 0 null 0 null 0
> rows: 1
-- Query #2: should return one row
......@@ -2716,27 +2716,27 @@ is null;
select * from one natural join two left join two three on
one.id=three.id left join one four on two.id=four.id where
three.val>=DATE'2006-07-01';
> ID ID VAL ID VAL ID
> -- -- ---------- -- ---------- --
> 2 2 2006-07-01 2 2006-07-01 2
> ID VAL ID VAL ID
> -- ---------- -- ---------- --
> 2 2006-07-01 2 2006-07-01 2
> rows: 1
-- Query #3: should return the union of #1 and #2
select * from one natural join two left join two three on
one.id=three.id left join one four on two.id=four.id where three.val
is null or three.val>=DATE'2006-07-01';
> ID ID VAL ID VAL ID
> -- -- ---------- -- ---------- --
> 0 0 null 0 null 0
> 2 2 2006-07-01 2 2006-07-01 2
> ID VAL ID VAL ID
> -- ---------- -- ---------- --
> 0 null 0 null 0
> 2 2006-07-01 2 2006-07-01 2
> rows: 2
explain select * from one natural join two left join two three on
one.id=three.id left join one four on two.id=four.id where three.val
is null or three.val>=DATE'2006-07-01';
> PLAN
> -----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT ONE.ID, TWO.ID, TWO.VAL, THREE.ID, THREE.VAL, FOUR.ID FROM PUBLIC.ONE /* PUBLIC.ONE_TABLE_SCAN */ INNER JOIN PUBLIC.TWO /* PUBLIC.PRIMARY_KEY_14: ID = PUBLIC.ONE.ID AND ID = PUBLIC.ONE.ID */ ON 1=1 /* WHERE PUBLIC.ONE.ID = PUBLIC.TWO.ID */ LEFT OUTER JOIN PUBLIC.TWO THREE /* PUBLIC.PRIMARY_KEY_14: ID = ONE.ID */ ON ONE.ID = THREE.ID LEFT OUTER JOIN PUBLIC.ONE FOUR /* PUBLIC.PRIMARY_KEY_1: ID = TWO.ID */ ON TWO.ID = FOUR.ID WHERE (PUBLIC.ONE.ID = PUBLIC.TWO.ID) AND ((THREE.VAL IS NULL) OR (THREE.VAL >= DATE '2006-07-01'))
> ---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT ONE.ID, TWO.VAL, THREE.ID, THREE.VAL, FOUR.ID FROM PUBLIC.ONE /* PUBLIC.ONE_TABLE_SCAN */ INNER JOIN PUBLIC.TWO /* PUBLIC.PRIMARY_KEY_14: ID = PUBLIC.ONE.ID AND ID = PUBLIC.ONE.ID */ ON 1=1 /* WHERE PUBLIC.ONE.ID = PUBLIC.TWO.ID */ LEFT OUTER JOIN PUBLIC.TWO THREE /* PUBLIC.PRIMARY_KEY_14: ID = ONE.ID */ ON ONE.ID = THREE.ID LEFT OUTER JOIN PUBLIC.ONE FOUR /* PUBLIC.PRIMARY_KEY_1: ID = TWO.ID */ ON TWO.ID = FOUR.ID WHERE (PUBLIC.ONE.ID = PUBLIC.TWO.ID) AND ((THREE.VAL IS NULL) OR (THREE.VAL >= DATE '2006-07-01'))
> rows: 1
-- Query #4: same as #3, but the joins have been manually re-ordered
......@@ -2744,10 +2744,10 @@ is null or three.val>=DATE'2006-07-01';
select * from one natural join two left join one four on
two.id=four.id left join two three on one.id=three.id where three.val
is null or three.val>=DATE'2006-07-01';
> ID ID VAL ID ID VAL
> -- -- ---------- -- -- ----------
> 0 0 null 0 0 null
> 2 2 2006-07-01 2 2 2006-07-01
> ID VAL ID ID VAL
> -- ---------- -- -- ----------
> 0 null 0 0 null
> 2 2006-07-01 2 2 2006-07-01
> rows: 2
drop table one;
......@@ -3659,9 +3659,9 @@ select * from left_hand left join right_hand on left_hand.id=right_hand.id;
-- h2: 1 (2 cols); postgresql, mysql: 1 (1 col); derby, hsqldb: no natural join
select * from left_hand natural join right_hand;
> ID ID
> -- --
> 0 0
> ID
> --
> 0
> rows: 1
-- h2, postgresql, mysql, derby, hsqldb: 1
......@@ -3680,8 +3680,8 @@ select * from left_hand left join right_hand on left_hand.id=right_hand.id where
-- h2: 0 (2 cols); postgresql, mysql: 0 (1 col); derby, hsqldb: no natural join
select * from left_hand natural join right_hand where left_hand.id=1;
> ID ID
> -- --
> ID
> --
> rows: 0
-- !!! h2: 1; postgresql, mysql, hsqldb: 0; derby: exception
......@@ -3714,8 +3714,8 @@ select * from left_hand left join right_hand on left_hand.id=right_hand.id where
-- h2: 0 rows; postgresql, mysql: exception; derby, hsqldb: no natural join
select * from left_hand natural join right_hand where left_hand.id=1 group by left_hand.id having right_hand.id=2;
> ID ID
> -- --
> ID
> --
> rows: 0
drop table right_hand;
......@@ -6141,14 +6141,14 @@ select * from t1 cross join t2;
> rows: 4
select * from t1 natural join t2;
> ID NAME ID NAME
> -- ---- -- ----
> ID NAME
> -- ----
> rows: 0
explain select * from t1 natural join t2;
> PLAN
> ----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT T1.ID, T1.NAME, T2.ID, T2.NAME FROM PUBLIC.T1 /* PUBLIC.T1_TABLE_SCAN */ INNER JOIN PUBLIC.T2 /* PUBLIC.T2_TABLE_SCAN */ ON 1=1 WHERE (PUBLIC.T1.ID = PUBLIC.T2.ID) AND (PUBLIC.T1.NAME = PUBLIC.T2.NAME)
> ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT T1.ID, T1.NAME FROM PUBLIC.T1 /* PUBLIC.T1_TABLE_SCAN */ INNER JOIN PUBLIC.T2 /* PUBLIC.T2_TABLE_SCAN */ ON 1=1 WHERE (PUBLIC.T1.ID = PUBLIC.T2.ID) AND (PUBLIC.T1.NAME = PUBLIC.T2.NAME)
> rows: 1
drop table t1;
......@@ -6176,16 +6176,16 @@ insert into INVOICE_LINE values(10, 1, 0, 'Super Soap'), (20, 1, 0, 'Regular Soa
> update count: 2
select c.*, i.*, l.* from customer c natural join invoice i natural join INVOICE_LINE l;
> CUSTOMERID CUSTOMER_NAME CUSTOMERID INVOICEID INVOICE_TEXT LINE_ID INVOICEID CUSTOMERID LINE_TEXT
> ---------- ------------- ---------- --------- ------------ ------- --------- ---------- ------------
> 0 Acme 0 1 Soap 10 1 0 Super Soap
> 0 Acme 0 1 Soap 20 1 0 Regular Soap
> CUSTOMERID CUSTOMER_NAME INVOICEID INVOICE_TEXT LINE_ID LINE_TEXT
> ---------- ------------- --------- ------------ ------- ------------
> 0 Acme 1 Soap 10 Super Soap
> 0 Acme 1 Soap 20 Regular Soap
> rows: 2
explain select c.*, i.*, l.* from customer c natural join invoice i natural join INVOICE_LINE l;
> PLAN
> --------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT C.CUSTOMERID, C.CUSTOMER_NAME, I.CUSTOMERID, I.INVOICEID, I.INVOICE_TEXT, L.LINE_ID, L.INVOICEID, L.CUSTOMERID, L.LINE_TEXT FROM PUBLIC.CUSTOMER C /* PUBLIC.CUSTOMER_TABLE_SCAN */ INNER JOIN PUBLIC.INVOICE I /* PUBLIC.INVOICE_TABLE_SCAN */ ON 1=1 /* WHERE PUBLIC.C.CUSTOMERID = PUBLIC.I.CUSTOMERID */ INNER JOIN PUBLIC.INVOICE_LINE L /* PUBLIC.INVOICE_LINE_TABLE_SCAN */ ON 1=1 WHERE (PUBLIC.C.CUSTOMERID = PUBLIC.I.CUSTOMERID) AND ((PUBLIC.I.CUSTOMERID = PUBLIC.L.CUSTOMERID) AND (PUBLIC.I.INVOICEID = PUBLIC.L.INVOICEID))
> ---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> SELECT C.CUSTOMERID, C.CUSTOMER_NAME, I.INVOICEID, I.INVOICE_TEXT, L.LINE_ID, L.LINE_TEXT FROM PUBLIC.CUSTOMER C /* PUBLIC.CUSTOMER_TABLE_SCAN */ INNER JOIN PUBLIC.INVOICE I /* PUBLIC.INVOICE_TABLE_SCAN */ ON 1=1 /* WHERE PUBLIC.C.CUSTOMERID = PUBLIC.I.CUSTOMERID */ INNER JOIN PUBLIC.INVOICE_LINE L /* PUBLIC.INVOICE_LINE_TABLE_SCAN */ ON 1=1 WHERE (PUBLIC.C.CUSTOMERID = PUBLIC.I.CUSTOMERID) AND ((PUBLIC.I.CUSTOMERID = PUBLIC.L.CUSTOMERID) AND (PUBLIC.I.INVOICEID = PUBLIC.L.INVOICEID))
> rows: 1
drop table customer;
......
Markdown 格式
0%
您添加了 0 到此讨论。请谨慎行事。
请先完成此评论的编辑!
注册 或者 后发表评论