On 2019-12-31 00:07, Vik Fearing wrote:
One thing I notice is that the joined columns are still accessible from
their respective table names when they should not be per spec. That
might be one of those "silly restrictions" that we choose to ignore, but
it should probably be noted somewhere, at the very least in a code
comment if not in user documentation. (This is my reading of SQL:2016 SR
11.a.i)
Here is a rebased patch.
The above comment is valid. One reason I didn't implement it is that it
would create inconsistencies with existing behavior, which is already
nonstandard.
For example,
create table a (id int, a1 int, a2 int);
create table b (id int, b2 int, b3 int);
makes
select a.id from a join b using (id);
invalid. Adding an explicit alias for the common column names doesn't
change that semantically, because an implicit alias also exists if an
explicit one isn't specified.
I agree that some documentation would be in order if we decide to leave
it like this.
Another reason was that it seemed "impossible" to implement it before
Tom's recent refactoring of the parse namespace handling. Now we also
have parse namespace columns tracked separately from range table
entries, so it appears that this would be possible. If we want to do it.
--
Peter Eisentraut http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
From 954b3c9b2a7eab3fc4c15a9777d0f829a6a0382d Mon Sep 17 00:00:00 2001
From: Peter Eisentraut <pe...@eisentraut.org>
Date: Mon, 27 Jan 2020 09:52:44 +0100
Subject: [PATCH v3] Allow an alias to be attached to a JOIN ... USING
This allows something like
SELECT ... FROM t1 JOIN t2 USING (a, b, c) AS x
where x has the columns a, b, c and unlike a regular alias it does not
hide the range variables of the tables being joined t1 and t2.
Per SQL:2016 feature F404 "Range variable for common column names".
Discussion:
https://www.postgresql.org/message-id/flat/454638cf-d563-ab76-a585-256442806...@2ndquadrant.com
---
doc/src/sgml/ref/select.sgml | 11 +++-
src/backend/catalog/sql_features.txt | 2 +-
src/backend/nodes/copyfuncs.c | 2 +
src/backend/nodes/equalfuncs.c | 2 +
src/backend/nodes/outfuncs.c | 2 +
src/backend/nodes/readfuncs.c | 2 +
src/backend/parser/analyze.c | 1 +
src/backend/parser/gram.y | 69 +++++++++++++++--------
src/backend/parser/parse_clause.c | 21 ++++++-
src/backend/parser/parse_relation.c | 45 ++++++++++++++-
src/backend/utils/adt/ruleutils.c | 4 ++
src/include/nodes/parsenodes.h | 7 +++
src/include/nodes/primnodes.h | 1 +
src/include/parser/parse_node.h | 1 +
src/include/parser/parse_relation.h | 1 +
src/test/regress/expected/create_view.out | 52 ++++++++++++++++-
src/test/regress/expected/join.out | 31 ++++++++++
src/test/regress/sql/create_view.sql | 11 ++++
src/test/regress/sql/join.sql | 8 +++
19 files changed, 243 insertions(+), 30 deletions(-)
diff --git a/doc/src/sgml/ref/select.sgml b/doc/src/sgml/ref/select.sgml
index 691e402803..36416085c1 100644
--- a/doc/src/sgml/ref/select.sgml
+++ b/doc/src/sgml/ref/select.sgml
@@ -59,7 +59,7 @@
[ LATERAL ] <replaceable class="parameter">function_name</replaceable> ( [
<replaceable class="parameter">argument</replaceable> [, ...] ] ) AS (
<replaceable class="parameter">column_definition</replaceable> [, ...] )
[ LATERAL ] ROWS FROM( <replaceable
class="parameter">function_name</replaceable> ( [ <replaceable
class="parameter">argument</replaceable> [, ...] ] ) [ AS ( <replaceable
class="parameter">column_definition</replaceable> [, ...] ) ] [, ...] )
[ WITH ORDINALITY ] [ [ AS ] <replaceable
class="parameter">alias</replaceable> [ ( <replaceable
class="parameter">column_alias</replaceable> [, ...] ) ] ]
- <replaceable class="parameter">from_item</replaceable> [ NATURAL ]
<replaceable class="parameter">join_type</replaceable> <replaceable
class="parameter">from_item</replaceable> [ ON <replaceable
class="parameter">join_condition</replaceable> | USING ( <replaceable
class="parameter">join_column</replaceable> [, ...] ) ]
+ <replaceable class="parameter">from_item</replaceable> [ NATURAL ]
<replaceable class="parameter">join_type</replaceable> <replaceable
class="parameter">from_item</replaceable> [ ON <replaceable
class="parameter">join_condition</replaceable> | USING ( <replaceable
class="parameter">join_column</replaceable> [, ...] ) [ AS <replaceable
class="parameter">join_using_alias</replaceable> ] ]
<phrase>and <replaceable class="parameter">grouping_element</replaceable> can
be one of:</phrase>
@@ -638,6 +638,15 @@ <title id="sql-from-title"><literal>FROM</literal>
Clause</title>
equivalent columns will be included in the join output, not
both.
</para>
+
+ <para>
+ If a <replaceable class="parameter">join_using_alias</replaceable> is
+ specified, it gives a correlation name to the join columns. Only the
+ join columns in the <literal>USING</literal> clause are addressable by
+ this name. Unlike an <replaceable
+ class="parameter">alias</replaceable>, this does not hide the names of
+ the joined tables from the rest of the query.
+ </para>
</listitem>
</varlistentry>
diff --git a/src/backend/catalog/sql_features.txt
b/src/backend/catalog/sql_features.txt
index 9f840ddfd2..0e0d8d0b3b 100644
--- a/src/backend/catalog/sql_features.txt
+++ b/src/backend/catalog/sql_features.txt
@@ -264,7 +264,7 @@ F401 Extended joined table 02 FULL OUTER JOIN
YES
F401 Extended joined table 04 CROSS JOIN YES
F402 Named column joins for LOBs, arrays, and multisets
YES
F403 Partitioned joined tables NO
-F404 Range variable for common column names NO
+F404 Range variable for common column names YES
F411 Time zone specification YES differences regarding
literal interpretation
F421 National character YES
F431 Read-only scrollable cursors YES
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 54ad62bb7f..6ce71fcc2d 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -2168,6 +2168,7 @@ _copyJoinExpr(const JoinExpr *from)
COPY_NODE_FIELD(rarg);
COPY_NODE_FIELD(usingClause);
COPY_NODE_FIELD(quals);
+ COPY_NODE_FIELD(join_using_alias);
COPY_NODE_FIELD(alias);
COPY_SCALAR_FIELD(rtindex);
@@ -2377,6 +2378,7 @@ _copyRangeTblEntry(const RangeTblEntry *from)
COPY_NODE_FIELD(joinaliasvars);
COPY_NODE_FIELD(joinleftcols);
COPY_NODE_FIELD(joinrightcols);
+ COPY_NODE_FIELD(join_using_alias);
COPY_NODE_FIELD(functions);
COPY_SCALAR_FIELD(funcordinality);
COPY_NODE_FIELD(tablefunc);
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index 5b1ba143b1..8a56786538 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -788,6 +788,7 @@ _equalJoinExpr(const JoinExpr *a, const JoinExpr *b)
COMPARE_NODE_FIELD(rarg);
COMPARE_NODE_FIELD(usingClause);
COMPARE_NODE_FIELD(quals);
+ COMPARE_NODE_FIELD(join_using_alias);
COMPARE_NODE_FIELD(alias);
COMPARE_SCALAR_FIELD(rtindex);
@@ -2665,6 +2666,7 @@ _equalRangeTblEntry(const RangeTblEntry *a, const
RangeTblEntry *b)
COMPARE_NODE_FIELD(joinaliasvars);
COMPARE_NODE_FIELD(joinleftcols);
COMPARE_NODE_FIELD(joinrightcols);
+ COMPARE_NODE_FIELD(join_using_alias);
COMPARE_NODE_FIELD(functions);
COMPARE_SCALAR_FIELD(funcordinality);
COMPARE_NODE_FIELD(tablefunc);
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index d76fae44b8..be15d31a94 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -1659,6 +1659,7 @@ _outJoinExpr(StringInfo str, const JoinExpr *node)
WRITE_NODE_FIELD(rarg);
WRITE_NODE_FIELD(usingClause);
WRITE_NODE_FIELD(quals);
+ WRITE_NODE_FIELD(join_using_alias);
WRITE_NODE_FIELD(alias);
WRITE_INT_FIELD(rtindex);
}
@@ -3075,6 +3076,7 @@ _outRangeTblEntry(StringInfo str, const RangeTblEntry
*node)
WRITE_NODE_FIELD(joinaliasvars);
WRITE_NODE_FIELD(joinleftcols);
WRITE_NODE_FIELD(joinrightcols);
+ WRITE_NODE_FIELD(join_using_alias);
break;
case RTE_FUNCTION:
WRITE_NODE_FIELD(functions);
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index 551ce6c41c..5852131fb8 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -1302,6 +1302,7 @@ _readJoinExpr(void)
READ_NODE_FIELD(rarg);
READ_NODE_FIELD(usingClause);
READ_NODE_FIELD(quals);
+ READ_NODE_FIELD(join_using_alias);
READ_NODE_FIELD(alias);
READ_INT_FIELD(rtindex);
@@ -1404,6 +1405,7 @@ _readRangeTblEntry(void)
READ_NODE_FIELD(joinaliasvars);
READ_NODE_FIELD(joinleftcols);
READ_NODE_FIELD(joinrightcols);
+ READ_NODE_FIELD(join_using_alias);
break;
case RTE_FUNCTION:
READ_NODE_FIELD(functions);
diff --git a/src/backend/parser/analyze.c b/src/backend/parser/analyze.c
index 748bebffc1..9bbe4632f8 100644
--- a/src/backend/parser/analyze.c
+++ b/src/backend/parser/analyze.c
@@ -1739,6 +1739,7 @@ transformSetOperationStmt(ParseState *pstate, SelectStmt
*stmt)
NIL,
NIL,
NULL,
+
NULL,
false);
sv_namespace = pstate->p_namespace;
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index ba5916b4d2..50a80de856 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -437,7 +437,7 @@ static Node *makeRecursiveViewSelect(char *relname, List
*aliases, Node *query);
%type <list> locked_rels_list
%type <boolean> all_or_distinct
-%type <node> join_outer join_qual
+%type <node> join_outer
%type <jtype> join_type
%type <list> extract_list overlay_list position_list
@@ -490,7 +490,7 @@ static Node *makeRecursiveViewSelect(char *relname, List
*aliases, Node *query);
%type <ival> sub_type opt_materialized
%type <value> NumericOnly
%type <list> NumericOnly_list
-%type <alias> alias_clause opt_alias_clause
+%type <alias> alias_clause opt_alias_clause opt_alias_clause_for_join_using
%type <list> func_alias_clause
%type <sortby> sortby
%type <ielem> index_elem
@@ -12079,20 +12079,28 @@ joined_table:
n->quals = NULL;
$$ = n;
}
- | table_ref join_type JOIN table_ref join_qual
+ | table_ref join_type JOIN table_ref ON a_expr
{
JoinExpr *n = makeNode(JoinExpr);
n->jointype = $2;
n->isNatural = false;
n->larg = $1;
n->rarg = $4;
- if ($5 != NULL && IsA($5, List))
- n->usingClause = (List *) $5;
/* USING clause */
- else
- n->quals = $5; /* ON clause */
+ n->quals = $6;
+ $$ = n;
+ }
+ | table_ref join_type JOIN table_ref USING '('
name_list ')' opt_alias_clause_for_join_using
+ {
+ JoinExpr *n = makeNode(JoinExpr);
+ n->jointype = $2;
+ n->isNatural = false;
+ n->larg = $1;
+ n->rarg = $4;
+ n->usingClause = $7;
+ n->join_using_alias = $9; /* not
n->alias! */
$$ = n;
}
- | table_ref JOIN table_ref join_qual
+ | table_ref JOIN table_ref ON a_expr
{
/* letting join_type reduce to empty
doesn't work */
JoinExpr *n = makeNode(JoinExpr);
@@ -12100,10 +12108,19 @@ joined_table:
n->isNatural = false;
n->larg = $1;
n->rarg = $3;
- if ($4 != NULL && IsA($4, List))
- n->usingClause = (List *) $4;
/* USING clause */
- else
- n->quals = $4; /* ON clause */
+ n->quals = $5;
+ $$ = n;
+ }
+ | table_ref JOIN table_ref USING '(' name_list ')'
opt_alias_clause_for_join_using
+ {
+ /* letting join_type reduce to empty
doesn't work */
+ JoinExpr *n = makeNode(JoinExpr);
+ n->jointype = JOIN_INNER;
+ n->isNatural = false;
+ n->larg = $1;
+ n->rarg = $3;
+ n->usingClause = $6;
+ n->join_using_alias = $8; /* not
n->alias! */
$$ = n;
}
| table_ref NATURAL join_type JOIN table_ref
@@ -12160,6 +12177,21 @@ opt_alias_clause: alias_clause
{ $$ = $1; }
| /*EMPTY*/
{ $$ = NULL; }
;
+/*
+ * The alias clause after JOIN ... USING only accepts the AS ColId spelling,
+ * per SQL standard. (The grammar could parse the other variants, but they
+ * don't seem to be useful, and it might lead to parser problems in the
+ * future.)
+ */
+opt_alias_clause_for_join_using:
+ AS ColId
+ {
+ $$ = makeNode(Alias);
+ $$->aliasname = $2;
+ }
+ | /*EMPTY*/
{ $$ = NULL; }
+ ;
+
/*
* func_alias_clause can include both an Alias and a coldeflist, so we make it
* return a 2-element list that gets disassembled by calling production.
@@ -12202,19 +12234,6 @@ join_outer: OUTER_P
{ $$ = NULL; }
| /*EMPTY*/
{ $$ = NULL; }
;
-/* JOIN qualification clauses
- * Possibilities are:
- * USING ( column list ) allows only unqualified column names,
- * which must match between
tables.
- * ON expr allows more general qualifications.
- *
- * We return USING as a List node, while an ON-expr will not be a List.
- */
-
-join_qual: USING '(' name_list ')' { $$ =
(Node *) $3; }
- | ON a_expr
{ $$ = $2; }
- ;
-
relation_expr:
qualified_name
diff --git a/src/backend/parser/parse_clause.c
b/src/backend/parser/parse_clause.c
index 36a3efff87..6e7ac5bc3b 100644
--- a/src/backend/parser/parse_clause.c
+++ b/src/backend/parser/parse_clause.c
@@ -1265,6 +1265,13 @@ transformFromClauseItem(ParseState *pstate, Node *n,
j->usingClause = rlist;
}
+ /*
+ * If a USING clause alias was specified, save the USING
columns as
+ * its column list.
+ */
+ if (j->join_using_alias)
+ j->join_using_alias->colnames = j->usingClause;
+
/*
* Now transform the join qualifications, if any.
*/
@@ -1462,6 +1469,7 @@ transformFromClauseItem(ParseState *pstate, Node *n,
res_colvars,
l_colnos,
r_colnos,
+
j->join_using_alias,
j->alias,
true);
@@ -1515,10 +1523,21 @@ transformFromClauseItem(ParseState *pstate, Node *n,
* The join RTE itself is always made visible for unqualified
column
* names. It's visible as a relation name only if it has an
alias.
*/
- nsitem->p_rel_visible = (j->alias != NULL);
+ nsitem->p_rel_visible = (j->alias != NULL ||
j->join_using_alias != NULL);
nsitem->p_cols_visible = true;
nsitem->p_lateral_only = false;
nsitem->p_lateral_ok = true;
+ nsitem->p_join_using_alias = (j->join_using_alias != NULL);
+
+ /*
+ * Check the JOIN/USING alias for namespace conflicts against
the
+ * subtrees (per SQL standard).
+ */
+ if (j->join_using_alias)
+ {
+ checkNameSpaceConflicts(pstate, list_make1(nsitem),
l_namespace);
+ checkNameSpaceConflicts(pstate, list_make1(nsitem),
r_namespace);
+ }
*top_nsitem = nsitem;
*namespace = lappend(my_namespace, nsitem);
diff --git a/src/backend/parser/parse_relation.c
b/src/backend/parser/parse_relation.c
index b875a50646..2b32f4af99 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -671,6 +671,37 @@ scanNSItemForColumn(ParseState *pstate, ParseNamespaceItem
*nsitem,
int attnum;
Var *var;
+ /*
+ * If this is a JOIN/USING alias, then check that the column is part of
+ * the USING column list. If so, let scanRTEForColumn() below do the
main
+ * work.
+ */
+ if (nsitem->p_join_using_alias)
+ {
+ ListCell *c;
+ bool found = false;
+
+ foreach(c, rte->join_using_alias->colnames)
+ {
+ const char *attcolname = strVal(lfirst(c));
+
+ if (strcmp(attcolname, colname) == 0)
+ {
+ found = true;
+ break;
+ }
+ }
+
+ if (!found)
+ ereport(ERROR,
+
(errcode(ERRCODE_INVALID_COLUMN_REFERENCE),
+ errmsg("column reference \"%s\" is
invalid",
+ colname),
+ errdetail("The range variable \"%s\"
only contains columns in the USING clause.",
+
rte->join_using_alias->aliasname),
+ parser_errposition(pstate, location)));
+ }
+
/*
* Scan the RTE's column names (or aliases) for a match. Complain if
* multiple matches.
@@ -1265,6 +1296,7 @@ buildNSItemFromTupleDesc(RangeTblEntry *rte, Index
rtindex, TupleDesc tupdesc)
nsitem->p_cols_visible = true;
nsitem->p_lateral_only = false;
nsitem->p_lateral_ok = true;
+ nsitem->p_join_using_alias = false;
return nsitem;
}
@@ -1326,6 +1358,7 @@ buildNSItemFromLists(RangeTblEntry *rte, Index rtindex,
nsitem->p_cols_visible = true;
nsitem->p_lateral_only = false;
nsitem->p_lateral_ok = true;
+ nsitem->p_join_using_alias = false;
return nsitem;
}
@@ -2105,6 +2138,7 @@ addRangeTableEntryForJoin(ParseState *pstate,
List *aliasvars,
List *leftcols,
List *rightcols,
+ Alias *join_using_alias,
Alias *alias,
bool inFromCl)
{
@@ -2133,9 +2167,16 @@ addRangeTableEntryForJoin(ParseState *pstate,
rte->joinaliasvars = aliasvars;
rte->joinleftcols = leftcols;
rte->joinrightcols = rightcols;
+ rte->join_using_alias = join_using_alias;
rte->alias = alias;
- eref = alias ? copyObject(alias) : makeAlias("unnamed_join", NIL);
+ if (alias)
+ eref = copyObject(alias);
+ else if (join_using_alias)
+ eref = copyObject(join_using_alias);
+ else
+ eref = makeAlias("unnamed_join", NIL);
+
numaliases = list_length(eref->colnames);
/* fill in any unspecified alias columns */
@@ -2181,6 +2222,7 @@ addRangeTableEntryForJoin(ParseState *pstate,
nsitem->p_cols_visible = true;
nsitem->p_lateral_only = false;
nsitem->p_lateral_ok = true;
+ nsitem->p_join_using_alias = false;
return nsitem;
}
@@ -2481,6 +2523,7 @@ addNSItemToQuery(ParseState *pstate, ParseNamespaceItem
*nsitem,
nsitem->p_cols_visible = addToVarNameSpace;
nsitem->p_lateral_only = false;
nsitem->p_lateral_ok = true;
+ nsitem->p_join_using_alias = false;
pstate->p_namespace = lappend(pstate->p_namespace, nsitem);
}
}
diff --git a/src/backend/utils/adt/ruleutils.c
b/src/backend/utils/adt/ruleutils.c
index 116e00bce4..98abfb9ca0 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -10362,6 +10362,10 @@ get_from_clause_item(Node *jtnode, Query *query,
deparse_context *context)
appendStringInfoString(buf,
quote_identifier(colname));
}
appendStringInfoChar(buf, ')');
+
+ if (j->join_using_alias)
+ appendStringInfo(buf, " AS %s",
+
quote_identifier(j->join_using_alias->aliasname));
}
else if (j->quals)
{
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index da0706add5..4b32a04bce 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1050,6 +1050,13 @@ typedef struct RangeTblEntry
List *joinleftcols; /* left-side input column numbers */
List *joinrightcols; /* right-side input column numbers */
+ /*
+ * join_using_alias is an alias clause attached directly to JOIN/USING.
+ * It is different from the alias field (below) in that it does not hide
+ * the range variables of the tables being joined.
+ */
+ Alias *join_using_alias;
+
/*
* Fields valid for a function RTE (else NIL/zero):
*
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index d73be2ad46..121e4b170d 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1491,6 +1491,7 @@ typedef struct JoinExpr
Node *rarg; /* right subtree */
List *usingClause; /* USING clause, if any (list of
String) */
Node *quals; /* qualifiers on join, if any */
+ Alias *join_using_alias; /* alias attached to USING clause */
Alias *alias; /* user-written alias clause,
if any */
int rtindex; /* RT index assigned
for join, or 0 */
} JoinExpr;
diff --git a/src/include/parser/parse_node.h b/src/include/parser/parse_node.h
index d25819aa28..7c17f3c46e 100644
--- a/src/include/parser/parse_node.h
+++ b/src/include/parser/parse_node.h
@@ -262,6 +262,7 @@ struct ParseNamespaceItem
bool p_cols_visible; /* Column names visible as unqualified
refs? */
bool p_lateral_only; /* Is only visible to LATERAL
expressions? */
bool p_lateral_ok; /* If so, does join type allow use? */
+ bool p_join_using_alias; /* Is it a JOIN/USING alias? */
};
/*
diff --git a/src/include/parser/parse_relation.h
b/src/include/parser/parse_relation.h
index 93f94466a0..bde59315d8 100644
--- a/src/include/parser/parse_relation.h
+++ b/src/include/parser/parse_relation.h
@@ -89,6 +89,7 @@ extern ParseNamespaceItem
*addRangeTableEntryForJoin(ParseState *pstate,
List *aliasvars,
List *leftcols,
List *rightcols,
+
Alias *joinalias,
Alias *alias,
bool inFromCl);
extern ParseNamespaceItem *addRangeTableEntryForCTE(ParseState *pstate,
diff --git a/src/test/regress/expected/create_view.out
b/src/test/regress/expected/create_view.out
index f10a3a7a12..c46a9f1bc3 100644
--- a/src/test/regress/expected/create_view.out
+++ b/src/test/regress/expected/create_view.out
@@ -805,6 +805,51 @@ View definition:
(tbl3
CROSS JOIN tbl4) same;
+create table tbl1a (a int, c int);
+create view view_of_joins_2a as select * from tbl1 join tbl1a using (a);
+create view view_of_joins_2b as select * from tbl1 join tbl1a using (a) as x;
+create view view_of_joins_2c as select * from (tbl1 join tbl1a using (a)) as y;
+create view view_of_joins_2d as select * from (tbl1 join tbl1a using (a) as x)
as y;
+select pg_get_viewdef('view_of_joins_2a', true);
+ pg_get_viewdef
+----------------------------
+ SELECT tbl1.a, +
+ tbl1.b, +
+ tbl1a.c +
+ FROM tbl1 +
+ JOIN tbl1a USING (a);
+(1 row)
+
+select pg_get_viewdef('view_of_joins_2b', true);
+ pg_get_viewdef
+---------------------------------
+ SELECT tbl1.a, +
+ tbl1.b, +
+ tbl1a.c +
+ FROM tbl1 +
+ JOIN tbl1a USING (a) AS x;
+(1 row)
+
+select pg_get_viewdef('view_of_joins_2c', true);
+ pg_get_viewdef
+-------------------------------
+ SELECT y.a, +
+ y.b, +
+ y.c +
+ FROM (tbl1 +
+ JOIN tbl1a USING (a)) y;
+(1 row)
+
+select pg_get_viewdef('view_of_joins_2d', true);
+ pg_get_viewdef
+------------------------------------
+ SELECT y.a, +
+ y.b, +
+ y.c +
+ FROM (tbl1 +
+ JOIN tbl1a USING (a) AS x) y;
+(1 row)
+
-- Test view decompilation in the face of column addition/deletion/renaming
create table tt2 (a int, b int, c int);
create table tt3 (ax int8, b int2, c numeric);
@@ -1904,7 +1949,7 @@ drop cascades to view aliased_view_2
drop cascades to view aliased_view_3
drop cascades to view aliased_view_4
DROP SCHEMA testviewschm2 CASCADE;
-NOTICE: drop cascades to 67 other objects
+NOTICE: drop cascades to 72 other objects
DETAIL: drop cascades to table t1
drop cascades to view temporal1
drop cascades to view temporal2
@@ -1929,6 +1974,11 @@ drop cascades to view unspecified_types
drop cascades to table tt1
drop cascades to table tx1
drop cascades to view view_of_joins
+drop cascades to table tbl1a
+drop cascades to view view_of_joins_2a
+drop cascades to view view_of_joins_2b
+drop cascades to view view_of_joins_2c
+drop cascades to view view_of_joins_2d
drop cascades to table tt2
drop cascades to table tt3
drop cascades to table tt4
diff --git a/src/test/regress/expected/join.out
b/src/test/regress/expected/join.out
index 761376b007..5582961143 100644
--- a/src/test/regress/expected/join.out
+++ b/src/test/regress/expected/join.out
@@ -1621,6 +1621,37 @@ SELECT '' AS "xxx", *
| 4 | 1 | one | 2
(4 rows)
+-- test join using aliases
+SELECT * FROM J1_TBL JOIN J2_TBL USING (i) WHERE J1_TBL.t = 'one'; -- ok
+ i | j | t | k
+---+---+-----+----
+ 1 | 4 | one | -1
+(1 row)
+
+SELECT * FROM J1_TBL JOIN J2_TBL USING (i) AS x WHERE J1_TBL.t = 'one'; -- ok
+ i | j | t | k
+---+---+-----+----
+ 1 | 4 | one | -1
+(1 row)
+
+SELECT * FROM (J1_TBL JOIN J2_TBL USING (i)) AS x WHERE J1_TBL.t = 'one'; --
error
+ERROR: invalid reference to FROM-clause entry for table "j1_tbl"
+LINE 1: ... * FROM (J1_TBL JOIN J2_TBL USING (i)) AS x WHERE J1_TBL.t =...
+ ^
+HINT: There is an entry for table "j1_tbl", but it cannot be referenced from
this part of the query.
+SELECT * FROM J1_TBL JOIN J2_TBL USING (i) AS x WHERE x.i = 1; -- ok
+ i | j | t | k
+---+---+-----+----
+ 1 | 4 | one | -1
+(1 row)
+
+SELECT * FROM J1_TBL JOIN J2_TBL USING (i) AS x WHERE x.t = 'one'; -- error
+ERROR: column reference "t" is invalid
+LINE 1: ...CT * FROM J1_TBL JOIN J2_TBL USING (i) AS x WHERE x.t = 'one...
+ ^
+DETAIL: The range variable "x" only contains columns in the USING clause.
+SELECT * FROM J1_TBL a1 JOIN J2_TBL a2 USING (i) AS a1; -- error
+ERROR: table name "a1" specified more than once
--
-- NATURAL JOIN
-- Inner equi-join on all columns with the same name
diff --git a/src/test/regress/sql/create_view.sql
b/src/test/regress/sql/create_view.sql
index e7af0bf2fa..dd5b4cd5ee 100644
--- a/src/test/regress/sql/create_view.sql
+++ b/src/test/regress/sql/create_view.sql
@@ -328,6 +328,17 @@ CREATE VIEW aliased_view_4 AS
\d+ view_of_joins
+create table tbl1a (a int, c int);
+create view view_of_joins_2a as select * from tbl1 join tbl1a using (a);
+create view view_of_joins_2b as select * from tbl1 join tbl1a using (a) as x;
+create view view_of_joins_2c as select * from (tbl1 join tbl1a using (a)) as y;
+create view view_of_joins_2d as select * from (tbl1 join tbl1a using (a) as x)
as y;
+
+select pg_get_viewdef('view_of_joins_2a', true);
+select pg_get_viewdef('view_of_joins_2b', true);
+select pg_get_viewdef('view_of_joins_2c', true);
+select pg_get_viewdef('view_of_joins_2d', true);
+
-- Test view decompilation in the face of column addition/deletion/renaming
create table tt2 (a int, b int, c int);
diff --git a/src/test/regress/sql/join.sql b/src/test/regress/sql/join.sql
index 5fc6617369..a91d826a85 100644
--- a/src/test/regress/sql/join.sql
+++ b/src/test/regress/sql/join.sql
@@ -126,6 +126,14 @@ CREATE TABLE J2_TBL (
FROM J1_TBL t1 (a, b, c) JOIN J2_TBL t2 (a, b) USING (b)
ORDER BY b, t1.a;
+-- test join using aliases
+SELECT * FROM J1_TBL JOIN J2_TBL USING (i) WHERE J1_TBL.t = 'one'; -- ok
+SELECT * FROM J1_TBL JOIN J2_TBL USING (i) AS x WHERE J1_TBL.t = 'one'; -- ok
+SELECT * FROM (J1_TBL JOIN J2_TBL USING (i)) AS x WHERE J1_TBL.t = 'one'; --
error
+SELECT * FROM J1_TBL JOIN J2_TBL USING (i) AS x WHERE x.i = 1; -- ok
+SELECT * FROM J1_TBL JOIN J2_TBL USING (i) AS x WHERE x.t = 'one'; -- error
+SELECT * FROM J1_TBL a1 JOIN J2_TBL a2 USING (i) AS a1; -- error
+
--
-- NATURAL JOIN
base-commit: 3e4818e9dd5be294d97ca67012528cb1c0b0ccaa
--
2.25.0