Re: Using the query INTERSECTion - Mailing list pgsql-general

From Tom Lane
Subject Re: Using the query INTERSECTion
Date
Msg-id 21133.1182189658@sss.pgh.pa.us
Whole thread Raw
In response to Re: Using the query INTERSECTion  (Vincenzo Romano <vincenzo.romano@gmail.com>)
List pgsql-general
Vincenzo Romano <vincenzo.romano@gmail.com> writes:
> But now I have one more thing. The following command will fail with
> a syntax error:

> SELECT * FROM (SELECT 1 ) a INTERSECT (SELECT 2 ) b;

> Because of the second (harmless) table alias.
> In my mind it should work. Or not?

Not.  INTERSECT is not like JOIN from a syntactic perspective.
According to the SQL spec, "something INTERSECT something" is
a <query expression>, and the only way to put one of those into
a FROM-list is to wrap it with parens (making it a <subquery>)
and then put an alias after it.  This is because a FROM-list
is a list of <table reference>s, which have the syntax

         <table reference> ::=
                <table name> [ [ AS ] <correlation name>
                    [ <left paren> <derived column list> <right paren> ] ]
              | <derived table> [ AS ] <correlation name>
                    [ <left paren> <derived column list> <right paren> ]
              | <joined table>

         <derived table> ::= <table subquery>

This works:
    SELECT * FROM ((SELECT 1 ) INTERSECT (SELECT 2 )) a;

Aliases on the INTERSECT inputs don't work (and wouldn't have any
real use if they did).  Your original example is actually getting
parsed as

(SELECT * FROM (SELECT 1 ) a) INTERSECT (SELECT 2 ) b;

which is OK, if redundant, up to the extraneous "b".

            regards, tom lane

pgsql-general by date:

Previous
From: Andreas Kostyrka
Date:
Subject: Re: [pgsql-advocacy] [PERFORM] [ADMIN] Postgres VS Oracle
Next
From: "Matt Bartolome"
Date:
Subject: pg_resetxlog command not found