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". Reviewed-by: Vik Fearing <vik.fearing@2ndquadrant.com> Reviewed-by: Tom Lane <tgl@sss.pgh.pa.us> Discussion: https://www.postgresql.org/message-id/flat/454638cf-d563-ab76-a585-2564428062af@2ndquadrant.com
This commit is contained in:
parent
27e1f14563
commit
055fee7eb4
@ -59,7 +59,7 @@ SELECT [ ALL | DISTINCT [ ON ( <replaceable class="parameter">expression</replac
|
||||
[ 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>
|
||||
|
||||
@ -676,7 +676,7 @@ TABLE [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ * ]
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>USING ( <replaceable class="parameter">join_column</replaceable> [, ...] )</literal></term>
|
||||
<term><literal>USING ( <replaceable class="parameter">join_column</replaceable> [, ...] ) [ AS <replaceable class="parameter">join_using_alias</replaceable> ]</literal></term>
|
||||
<listitem>
|
||||
<para>
|
||||
A clause of the form <literal>USING ( a, b, ... )</literal> is
|
||||
@ -686,6 +686,18 @@ TABLE [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ * ]
|
||||
equivalent columns will be included in the join output, not
|
||||
both.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
If a <replaceable class="parameter">join_using_alias</replaceable>
|
||||
name is specified, it provides a table alias for the join columns.
|
||||
Only the join columns listed in the <literal>USING</literal> clause
|
||||
are addressable by this name. Unlike a regular <replaceable
|
||||
class="parameter">alias</replaceable>, this does not hide the names of
|
||||
the joined tables from the rest of the query. Also unlike a regular
|
||||
<replaceable class="parameter">alias</replaceable>, you cannot write a
|
||||
column alias list — the output names of the join columns are the
|
||||
same as they appear in the <literal>USING</literal> list.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
|
@ -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
|
||||
|
@ -2231,6 +2231,7 @@ _copyJoinExpr(const JoinExpr *from)
|
||||
COPY_NODE_FIELD(larg);
|
||||
COPY_NODE_FIELD(rarg);
|
||||
COPY_NODE_FIELD(usingClause);
|
||||
COPY_NODE_FIELD(join_using_alias);
|
||||
COPY_NODE_FIELD(quals);
|
||||
COPY_NODE_FIELD(alias);
|
||||
COPY_SCALAR_FIELD(rtindex);
|
||||
@ -2442,6 +2443,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);
|
||||
|
@ -790,6 +790,7 @@ _equalJoinExpr(const JoinExpr *a, const JoinExpr *b)
|
||||
COMPARE_NODE_FIELD(larg);
|
||||
COMPARE_NODE_FIELD(rarg);
|
||||
COMPARE_NODE_FIELD(usingClause);
|
||||
COMPARE_NODE_FIELD(join_using_alias);
|
||||
COMPARE_NODE_FIELD(quals);
|
||||
COMPARE_NODE_FIELD(alias);
|
||||
COMPARE_SCALAR_FIELD(rtindex);
|
||||
@ -2703,6 +2704,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);
|
||||
|
@ -1693,6 +1693,7 @@ _outJoinExpr(StringInfo str, const JoinExpr *node)
|
||||
WRITE_NODE_FIELD(larg);
|
||||
WRITE_NODE_FIELD(rarg);
|
||||
WRITE_NODE_FIELD(usingClause);
|
||||
WRITE_NODE_FIELD(join_using_alias);
|
||||
WRITE_NODE_FIELD(quals);
|
||||
WRITE_NODE_FIELD(alias);
|
||||
WRITE_INT_FIELD(rtindex);
|
||||
@ -3193,6 +3194,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);
|
||||
|
@ -1346,6 +1346,7 @@ _readJoinExpr(void)
|
||||
READ_NODE_FIELD(larg);
|
||||
READ_NODE_FIELD(rarg);
|
||||
READ_NODE_FIELD(usingClause);
|
||||
READ_NODE_FIELD(join_using_alias);
|
||||
READ_NODE_FIELD(quals);
|
||||
READ_NODE_FIELD(alias);
|
||||
READ_INT_FIELD(rtindex);
|
||||
@ -1449,6 +1450,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);
|
||||
|
@ -457,6 +457,7 @@ add_rte_to_flat_rtable(PlannerGlobal *glob, RangeTblEntry *rte)
|
||||
newrte->joinaliasvars = NIL;
|
||||
newrte->joinleftcols = NIL;
|
||||
newrte->joinrightcols = NIL;
|
||||
newrte->join_using_alias = NULL;
|
||||
newrte->functions = NIL;
|
||||
newrte->tablefunc = NULL;
|
||||
newrte->values_lists = NIL;
|
||||
|
@ -1365,6 +1365,7 @@ convert_ANY_sublink_to_join(PlannerInfo *root, SubLink *sublink,
|
||||
result->larg = NULL; /* caller must fill this in */
|
||||
result->rarg = (Node *) rtr;
|
||||
result->usingClause = NIL;
|
||||
result->join_using_alias = NULL;
|
||||
result->quals = quals;
|
||||
result->alias = NULL;
|
||||
result->rtindex = 0; /* we don't need an RTE for it */
|
||||
@ -1519,6 +1520,7 @@ convert_EXISTS_sublink_to_join(PlannerInfo *root, SubLink *sublink,
|
||||
else
|
||||
result->rarg = (Node *) subselect->jointree;
|
||||
result->usingClause = NIL;
|
||||
result->join_using_alias = NULL;
|
||||
result->quals = whereClause;
|
||||
result->alias = NULL;
|
||||
result->rtindex = 0; /* we don't need an RTE for it */
|
||||
|
@ -1744,6 +1744,7 @@ transformSetOperationStmt(ParseState *pstate, SelectStmt *stmt)
|
||||
NIL,
|
||||
NIL,
|
||||
NULL,
|
||||
NULL,
|
||||
false);
|
||||
|
||||
sv_namespace = pstate->p_namespace;
|
||||
|
@ -509,7 +509,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 index_elem_options
|
||||
@ -12144,6 +12144,7 @@ joined_table:
|
||||
n->larg = $1;
|
||||
n->rarg = $4;
|
||||
n->usingClause = NIL;
|
||||
n->join_using_alias = NULL;
|
||||
n->quals = NULL;
|
||||
$$ = n;
|
||||
}
|
||||
@ -12155,9 +12156,16 @@ joined_table:
|
||||
n->larg = $1;
|
||||
n->rarg = $4;
|
||||
if ($5 != NULL && IsA($5, List))
|
||||
n->usingClause = (List *) $5; /* USING clause */
|
||||
{
|
||||
/* USING clause */
|
||||
n->usingClause = linitial_node(List, castNode(List, $5));
|
||||
n->join_using_alias = lsecond_node(Alias, castNode(List, $5));
|
||||
}
|
||||
else
|
||||
n->quals = $5; /* ON clause */
|
||||
{
|
||||
/* ON clause */
|
||||
n->quals = $5;
|
||||
}
|
||||
$$ = n;
|
||||
}
|
||||
| table_ref JOIN table_ref join_qual
|
||||
@ -12169,9 +12177,16 @@ joined_table:
|
||||
n->larg = $1;
|
||||
n->rarg = $3;
|
||||
if ($4 != NULL && IsA($4, List))
|
||||
n->usingClause = (List *) $4; /* USING clause */
|
||||
{
|
||||
/* USING clause */
|
||||
n->usingClause = linitial_node(List, castNode(List, $4));
|
||||
n->join_using_alias = lsecond_node(Alias, castNode(List, $4));
|
||||
}
|
||||
else
|
||||
n->quals = $4; /* ON clause */
|
||||
{
|
||||
/* ON clause */
|
||||
n->quals = $4;
|
||||
}
|
||||
$$ = n;
|
||||
}
|
||||
| table_ref NATURAL join_type JOIN table_ref
|
||||
@ -12182,6 +12197,7 @@ joined_table:
|
||||
n->larg = $1;
|
||||
n->rarg = $5;
|
||||
n->usingClause = NIL; /* figure out which columns later... */
|
||||
n->join_using_alias = NULL;
|
||||
n->quals = NULL; /* fill later */
|
||||
$$ = n;
|
||||
}
|
||||
@ -12194,6 +12210,7 @@ joined_table:
|
||||
n->larg = $1;
|
||||
n->rarg = $4;
|
||||
n->usingClause = NIL; /* figure out which columns later... */
|
||||
n->join_using_alias = NULL;
|
||||
n->quals = NULL; /* fill later */
|
||||
$$ = n;
|
||||
}
|
||||
@ -12228,6 +12245,22 @@ 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;
|
||||
/* the column name list will be inserted later */
|
||||
}
|
||||
| /*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.
|
||||
@ -12272,15 +12305,24 @@ opt_outer: OUTER_P
|
||||
|
||||
/* JOIN qualification clauses
|
||||
* Possibilities are:
|
||||
* USING ( column list ) allows only unqualified column names,
|
||||
* USING ( column list ) [ AS alias ]
|
||||
* 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.
|
||||
* We return USING as a two-element List (the first item being a sub-List
|
||||
* of the common column names, and the second either an Alias item or NULL).
|
||||
* An ON-expr will not be a List, so it can be told apart that way.
|
||||
*/
|
||||
|
||||
join_qual: USING '(' name_list ')' { $$ = (Node *) $3; }
|
||||
| ON a_expr { $$ = $2; }
|
||||
join_qual: USING '(' name_list ')' opt_alias_clause_for_join_using
|
||||
{
|
||||
$$ = (Node *) list_make2($3, $5);
|
||||
}
|
||||
| ON a_expr
|
||||
{
|
||||
$$ = $2;
|
||||
}
|
||||
;
|
||||
|
||||
|
||||
|
@ -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.
|
||||
*/
|
||||
@ -1460,6 +1467,7 @@ transformFromClauseItem(ParseState *pstate, Node *n,
|
||||
res_colvars,
|
||||
l_colnos,
|
||||
r_colnos,
|
||||
j->join_using_alias,
|
||||
j->alias,
|
||||
true);
|
||||
|
||||
@ -1493,6 +1501,30 @@ transformFromClauseItem(ParseState *pstate, Node *n,
|
||||
pstate->p_joinexprs = lappend(pstate->p_joinexprs, j);
|
||||
Assert(list_length(pstate->p_joinexprs) == j->rtindex);
|
||||
|
||||
/*
|
||||
* If the join has a USING alias, build a ParseNamespaceItem for that
|
||||
* and add it to the list of nsitems in the join's input.
|
||||
*/
|
||||
if (j->join_using_alias)
|
||||
{
|
||||
ParseNamespaceItem *jnsitem;
|
||||
|
||||
jnsitem = (ParseNamespaceItem *) palloc(sizeof(ParseNamespaceItem));
|
||||
jnsitem->p_names = j->join_using_alias;
|
||||
jnsitem->p_rte = nsitem->p_rte;
|
||||
jnsitem->p_rtindex = nsitem->p_rtindex;
|
||||
/* no need to copy the first N columns, just use res_nscolumns */
|
||||
jnsitem->p_nscolumns = res_nscolumns;
|
||||
/* set default visibility flags; might get changed later */
|
||||
jnsitem->p_rel_visible = true;
|
||||
jnsitem->p_cols_visible = true;
|
||||
jnsitem->p_lateral_only = false;
|
||||
jnsitem->p_lateral_ok = true;
|
||||
/* Per SQL, we must check for alias conflicts */
|
||||
checkNameSpaceConflicts(pstate, list_make1(jnsitem), my_namespace);
|
||||
my_namespace = lappend(my_namespace, jnsitem);
|
||||
}
|
||||
|
||||
/*
|
||||
* Prepare returned namespace list. If the JOIN has an alias then it
|
||||
* hides the contained RTEs completely; otherwise, the contained RTEs
|
||||
|
@ -2512,26 +2512,61 @@ static Node *
|
||||
transformWholeRowRef(ParseState *pstate, ParseNamespaceItem *nsitem,
|
||||
int sublevels_up, int location)
|
||||
{
|
||||
Var *result;
|
||||
|
||||
/*
|
||||
* Build the appropriate referencing node. Note that if the RTE is a
|
||||
* function returning scalar, we create just a plain reference to the
|
||||
* function value, not a composite containing a single column. This is
|
||||
* pretty inconsistent at first sight, but it's what we've done
|
||||
* historically. One argument for it is that "rel" and "rel.*" mean the
|
||||
* same thing for composite relations, so why not for scalar functions...
|
||||
* Build the appropriate referencing node. Normally this can be a
|
||||
* whole-row Var, but if the nsitem is a JOIN USING alias then it contains
|
||||
* only a subset of the columns of the underlying join RTE, so that will
|
||||
* not work. Instead we immediately expand the reference into a RowExpr.
|
||||
* Since the JOIN USING's common columns are fully determined at this
|
||||
* point, there seems no harm in expanding it now rather than during
|
||||
* planning.
|
||||
*
|
||||
* Note that if the RTE is a function returning scalar, we create just a
|
||||
* plain reference to the function value, not a composite containing a
|
||||
* single column. This is pretty inconsistent at first sight, but it's
|
||||
* what we've done historically. One argument for it is that "rel" and
|
||||
* "rel.*" mean the same thing for composite relations, so why not for
|
||||
* scalar functions...
|
||||
*/
|
||||
result = makeWholeRowVar(nsitem->p_rte, nsitem->p_rtindex,
|
||||
sublevels_up, true);
|
||||
if (nsitem->p_names == nsitem->p_rte->eref)
|
||||
{
|
||||
Var *result;
|
||||
|
||||
/* location is not filled in by makeWholeRowVar */
|
||||
result->location = location;
|
||||
result = makeWholeRowVar(nsitem->p_rte, nsitem->p_rtindex,
|
||||
sublevels_up, true);
|
||||
|
||||
/* mark relation as requiring whole-row SELECT access */
|
||||
markVarForSelectPriv(pstate, result);
|
||||
/* location is not filled in by makeWholeRowVar */
|
||||
result->location = location;
|
||||
|
||||
return (Node *) result;
|
||||
/* mark relation as requiring whole-row SELECT access */
|
||||
markVarForSelectPriv(pstate, result);
|
||||
|
||||
return (Node *) result;
|
||||
}
|
||||
else
|
||||
{
|
||||
RowExpr *rowexpr;
|
||||
List *fields;
|
||||
|
||||
/*
|
||||
* We want only as many columns as are listed in p_names->colnames,
|
||||
* and we should use those names not whatever possibly-aliased names
|
||||
* are in the RTE. We needn't worry about marking the RTE for SELECT
|
||||
* access, as the common columns are surely so marked already.
|
||||
*/
|
||||
expandRTE(nsitem->p_rte, nsitem->p_rtindex,
|
||||
sublevels_up, location, false,
|
||||
NULL, &fields);
|
||||
rowexpr = makeNode(RowExpr);
|
||||
rowexpr->args = list_truncate(fields,
|
||||
list_length(nsitem->p_names->colnames));
|
||||
rowexpr->row_typeid = RECORDOID;
|
||||
rowexpr->row_format = COERCE_IMPLICIT_CAST;
|
||||
rowexpr->colnames = copyObject(nsitem->p_names->colnames);
|
||||
rowexpr->location = location;
|
||||
|
||||
return (Node *) rowexpr;
|
||||
}
|
||||
}
|
||||
|
||||
/*
|
||||
|
@ -753,6 +753,12 @@ scanNSItemForColumn(ParseState *pstate, ParseNamespaceItem *nsitem,
|
||||
* else return InvalidAttrNumber.
|
||||
* If the name proves ambiguous within this RTE, raise error.
|
||||
*
|
||||
* Actually, we only search the names listed in "eref". This can be either
|
||||
* rte->eref, in which case we are indeed searching all the column names,
|
||||
* or for a join it can be rte->join_using_alias, in which case we are only
|
||||
* considering the common column names (which are the first N columns of the
|
||||
* join, so everything works).
|
||||
*
|
||||
* pstate and location are passed only for error-reporting purposes.
|
||||
*
|
||||
* Side effect: if fuzzystate is non-NULL, check non-system columns
|
||||
@ -2134,6 +2140,7 @@ addRangeTableEntryForJoin(ParseState *pstate,
|
||||
List *aliasvars,
|
||||
List *leftcols,
|
||||
List *rightcols,
|
||||
Alias *join_using_alias,
|
||||
Alias *alias,
|
||||
bool inFromCl)
|
||||
{
|
||||
@ -2162,6 +2169,7 @@ 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);
|
||||
|
@ -10813,6 +10813,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)
|
||||
{
|
||||
|
@ -1069,6 +1069,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):
|
||||
*
|
||||
|
@ -1499,6 +1499,11 @@ typedef struct RangeTblRef
|
||||
* alias has a critical impact on semantics, because a join with an alias
|
||||
* restricts visibility of the tables/columns inside it.
|
||||
*
|
||||
* join_using_alias is an Alias node representing the join correlation
|
||||
* name that SQL:2016 and later allow to be attached to JOIN/USING.
|
||||
* Its column alias list includes only the common column names from USING,
|
||||
* and it does not restrict visibility of the join's input tables.
|
||||
*
|
||||
* During parse analysis, an RTE is created for the Join, and its index
|
||||
* is filled into rtindex. This RTE is present mainly so that Vars can
|
||||
* be created that refer to the outputs of the join. The planner sometimes
|
||||
@ -1514,6 +1519,7 @@ typedef struct JoinExpr
|
||||
Node *larg; /* left subtree */
|
||||
Node *rarg; /* right subtree */
|
||||
List *usingClause; /* USING clause, if any (list of String) */
|
||||
Alias *join_using_alias; /* alias attached to USING clause, if any */
|
||||
Node *quals; /* qualifiers on join, if any */
|
||||
Alias *alias; /* user-written alias clause, if any */
|
||||
int rtindex; /* RT index assigned for join, or 0 */
|
||||
|
@ -228,7 +228,10 @@ struct ParseState
|
||||
* An element of a namespace list.
|
||||
*
|
||||
* p_names contains the table name and column names exposed by this nsitem.
|
||||
* (Currently, it's always equal to p_rte->eref.)
|
||||
* (Typically it's equal to p_rte->eref, but for a JOIN USING alias it's
|
||||
* equal to p_rte->join_using_alias. Since the USING columns will be the
|
||||
* join's first N columns, the net effect is just that we expose only those
|
||||
* join columns via this nsitem.)
|
||||
*
|
||||
* p_rte and p_rtindex link to the underlying rangetable entry.
|
||||
*
|
||||
|
@ -88,6 +88,7 @@ extern ParseNamespaceItem *addRangeTableEntryForJoin(ParseState *pstate,
|
||||
List *aliasvars,
|
||||
List *leftcols,
|
||||
List *rightcols,
|
||||
Alias *joinalias,
|
||||
Alias *alias,
|
||||
bool inFromCl);
|
||||
extern ParseNamespaceItem *addRangeTableEntryForCTE(ParseState *pstate,
|
||||
|
@ -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);
|
||||
@ -1949,7 +1994,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 68 other objects
|
||||
NOTICE: drop cascades to 73 other objects
|
||||
DETAIL: drop cascades to table t1
|
||||
drop cascades to view temporal1
|
||||
drop cascades to view temporal2
|
||||
@ -1974,6 +2019,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
|
||||
|
@ -1621,6 +1621,58 @@ SELECT *
|
||||
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 x.t does not exist
|
||||
LINE 1: ...CT * FROM J1_TBL JOIN J2_TBL USING (i) AS x WHERE x.t = 'one...
|
||||
^
|
||||
SELECT * FROM (J1_TBL JOIN J2_TBL USING (i) AS x) AS xx WHERE x.i = 1; -- error (XXX could use better hint)
|
||||
ERROR: missing FROM-clause entry for table "x"
|
||||
LINE 1: ...ROM (J1_TBL JOIN J2_TBL USING (i) AS x) AS xx WHERE x.i = 1;
|
||||
^
|
||||
SELECT * FROM J1_TBL a1 JOIN J2_TBL a2 USING (i) AS a1; -- error
|
||||
ERROR: table name "a1" specified more than once
|
||||
SELECT x.* FROM J1_TBL JOIN J2_TBL USING (i) AS x WHERE J1_TBL.t = 'one';
|
||||
i
|
||||
---
|
||||
1
|
||||
(1 row)
|
||||
|
||||
SELECT ROW(x.*) FROM J1_TBL JOIN J2_TBL USING (i) AS x WHERE J1_TBL.t = 'one';
|
||||
row
|
||||
-----
|
||||
(1)
|
||||
(1 row)
|
||||
|
||||
SELECT row_to_json(x.*) FROM J1_TBL JOIN J2_TBL USING (i) AS x WHERE J1_TBL.t = 'one';
|
||||
row_to_json
|
||||
-------------
|
||||
{"i":1}
|
||||
(1 row)
|
||||
|
||||
--
|
||||
-- NATURAL JOIN
|
||||
-- Inner equi-join on all columns with the same name
|
||||
|
@ -328,6 +328,17 @@ select * from
|
||||
|
||||
\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);
|
||||
|
@ -126,6 +126,17 @@ SELECT *
|
||||
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 JOIN J2_TBL USING (i) AS x) AS xx WHERE x.i = 1; -- error (XXX could use better hint)
|
||||
SELECT * FROM J1_TBL a1 JOIN J2_TBL a2 USING (i) AS a1; -- error
|
||||
SELECT x.* FROM J1_TBL JOIN J2_TBL USING (i) AS x WHERE J1_TBL.t = 'one';
|
||||
SELECT ROW(x.*) FROM J1_TBL JOIN J2_TBL USING (i) AS x WHERE J1_TBL.t = 'one';
|
||||
SELECT row_to_json(x.*) FROM J1_TBL JOIN J2_TBL USING (i) AS x WHERE J1_TBL.t = 'one';
|
||||
|
||||
--
|
||||
-- NATURAL JOIN
|
||||
|
Loading…
x
Reference in New Issue
Block a user