Queries
 
  query
 
 
  SELECT
 
 
  The previous chapters explained how to create tables, how to fill
  them with data, and how to manipulate that data.  Now we finally
  discuss how to retrieve the data from the database.
 
 
  Overview
  
   The process of retrieving or the command to retrieve data from a
   database is called a query.  In SQL the
    command is
   used to specify queries.  The general syntax of the
   SELECT command is
WITH with_queries SELECT select_list FROM table_expression sort_specification
   The following sections describe the details of the select list, the
   table expression, and the sort specification.  WITH>
   queries are treated last since they are an advanced feature.
  
  
   A simple kind of query has the form:
SELECT * FROM table1;
  Assuming that there is a table called table1,
  this command would retrieve all rows and all columns from
  table1.  (The method of retrieval depends on the
  client application.  For example, the
  psql program will display an ASCII-art
  table on the screen, while client libraries will offer functions to
  extract individual values from the query result.)  The select list
  specification * means all columns that the table
  expression happens to provide.  A select list can also select a
  subset of the available columns or make calculations using the
  columns.  For example, if
  table1 has columns named a>,
  b>, and c> (and perhaps others) you can make
  the following query:
SELECT a, b + c FROM table1;
  (assuming that b> and c> are of a numerical
  data type).
  See  for more details.
 
 
  FROM table1 is a simple kind of
  table expression: it reads just one table.  In general, table
  expressions can be complex constructs of base tables, joins, and
  subqueries.  But you can also omit the table expression entirely and
  use the SELECT command as a calculator:
SELECT 3 * 4;
  This is more useful if the expressions in the select list return
  varying results.  For example, you could call a function this way:
SELECT random();
  
 
 
  Table Expressions
  
   table expression
  
  
   A table expression computes a table.  The
   table expression contains a FROM> clause that is
   optionally followed by WHERE>, GROUP BY>, and
   HAVING> clauses.  Trivial table expressions simply refer
   to a table on disk, a so-called base table, but more complex
   expressions can be used to modify or combine base tables in various
   ways.
  
  
   The optional WHERE>, GROUP BY>, and
   HAVING> clauses in the table expression specify a
   pipeline of successive transformations performed on the table
   derived in the FROM> clause.  All these transformations
   produce a virtual table that provides the rows that are passed to
   the select list to compute the output rows of the query.
  
  
   The FROM Clause
   
    The  derives a
    table from one or more other tables given in a comma-separated
    table reference list.
FROM table_reference , table_reference , ...
    A table reference can be a table name (possibly schema-qualified),
    or a derived table such as a subquery, a table join, or complex
    combinations of these.  If more than one table reference is listed
    in the FROM> clause they are cross-joined (see below)
    to form the intermediate virtual table that can then be subject to
    transformations by the WHERE>, GROUP BY>,
    and HAVING> clauses and is finally the result of the
    overall table expression.
   
   
    ONLY
   
   
    When a table reference names a table that is the parent of a
    table inheritance hierarchy, the table reference produces rows of
    not only that table but all of its descendant tables, unless the
    key word ONLY> precedes the table name.  However, the
    reference produces only the columns that appear in the named table
    — any columns added in subtables are ignored.
   
   
    Joined Tables
    
     join
    
    
     A joined table is a table derived from two other (real or
     derived) tables according to the rules of the particular join
     type.  Inner, outer, and cross-joins are available.
    
    
     Join Types
     
      Cross join
      
       join
       cross
      
      
       cross join
      
      
T1 CROSS JOIN T2
       
        For every possible combination of rows from
        T1 and
        T2 (i.e., a Cartesian product),
        the joined table will contain a
        row consisting of all columns in T1
        followed by all columns in T2.  If
        the tables have N and M rows respectively, the joined
        table will have N * M rows.
       
       
        FROM T1 CROSS JOIN
        T2 is equivalent to
        FROM T1,
        T2.  It is also equivalent to
        FROM T1 INNER JOIN
        T2 ON TRUE (see below).
       
      
     
     
      Qualified joins
      
       join
       outer
      
      
       outer join
      
      
T1 { INNER | { LEFT | RIGHT | FULL } OUTER } JOIN T2 ON boolean_expression
T1 { INNER | { LEFT | RIGHT | FULL } OUTER } JOIN T2 USING ( join column list )
T1 NATURAL { INNER | { LEFT | RIGHT | FULL } OUTER } JOIN T2
       
        The words INNER and
        OUTER are optional in all forms.
        INNER is the default;
        LEFT, RIGHT, and
        FULL imply an outer join.
       
       
        The join condition is specified in the
        ON> or USING> clause, or implicitly by
        the word NATURAL>.  The join condition determines
        which rows from the two source tables are considered to
        match
, as explained in detail below.
       
       
        The ON> clause is the most general kind of join
        condition: it takes a Boolean value expression of the same
        kind as is used in a WHERE> clause.  A pair of rows
        from T1> and T2> match if the
        ON> expression evaluates to true for them.
       
       
        USING> is a shorthand notation: it takes a
        comma-separated list of column names, which the joined tables
        must have in common, and forms a join condition specifying
        equality of each of these pairs of columns.  Furthermore, the
        output of JOIN USING> has one column for each of
        the equated pairs of input columns, followed by the
        remaining columns from each table.  Thus, USING (a, b,
        c) is equivalent to ON (t1.a = t2.a AND
        t1.b = t2.b AND t1.c = t2.c) with the exception that
        if ON> is used there will be two columns
        a>, b>, and c> in the result,
        whereas with USING> there will be only one of each
        (and they will appear first if SELECT *> is used).
       
       
        
         join
         natural
        
        
         natural join
        
        Finally, NATURAL> is a shorthand form of
        USING>: it forms a USING> list
        consisting of all column names that appear in both
        input tables.  As with USING>, these columns appear
        only once in the output table.
       
       
        The possible types of qualified join are:
       
        
         INNER JOIN>
         
          
           For each row R1 of T1, the joined table has a row for each
           row in T2 that satisfies the join condition with R1.
          
         
        
        
         LEFT OUTER JOIN>
         
          join
          left
         
         
          left join
         
         
          
           First, an inner join is performed.  Then, for each row in
           T1 that does not satisfy the join condition with any row in
           T2, a joined row is added with null values in columns of
           T2.  Thus, the joined table always has at least
           one row for each row in T1.
          
         
        
        
         RIGHT OUTER JOIN>
         
          join
          right
         
         
          right join
         
         
          
           First, an inner join is performed.  Then, for each row in
           T2 that does not satisfy the join condition with any row in
           T1, a joined row is added with null values in columns of
           T1.  This is the converse of a left join: the result table
           will always have a row for each row in T2.
          
         
        
        
         FULL OUTER JOIN>
         
          
           First, an inner join is performed.  Then, for each row in
           T1 that does not satisfy the join condition with any row in
           T2, a joined row is added with null values in columns of
           T2.  Also, for each row of T2 that does not satisfy the
           join condition with any row in T1, a joined row with null
           values in the columns of T1 is added.
          
         
        
       
       
      
     
    
    
     Joins of all types can be chained together or nested: either or
     both T1 and
     T2 can be joined tables.  Parentheses
     can be used around JOIN> clauses to control the join
     order.  In the absence of parentheses, JOIN> clauses
     nest left-to-right.
    
    
     To put this together, assume we have tables t1:
 num | name
-----+------
   1 | a
   2 | b
   3 | c
     and t2:
 num | value
-----+-------
   1 | xxx
   3 | yyy
   5 | zzz
     then we get the following results for the various joins:
=>> SELECT * FROM t1 CROSS JOIN t2;>
 num | name | num | value
-----+------+-----+-------
   1 | a    |   1 | xxx
   1 | a    |   3 | yyy
   1 | a    |   5 | zzz
   2 | b    |   1 | xxx
   2 | b    |   3 | yyy
   2 | b    |   5 | zzz
   3 | c    |   1 | xxx
   3 | c    |   3 | yyy
   3 | c    |   5 | zzz
(9 rows)
=>> SELECT * FROM t1 INNER JOIN t2 ON t1.num = t2.num;>
 num | name | num | value
-----+------+-----+-------
   1 | a    |   1 | xxx
   3 | c    |   3 | yyy
(2 rows)
=>> SELECT * FROM t1 INNER JOIN t2 USING (num);>
 num | name | value
-----+------+-------
   1 | a    | xxx
   3 | c    | yyy
(2 rows)
=>> SELECT * FROM t1 NATURAL INNER JOIN t2;>
 num | name | value
-----+------+-------
   1 | a    | xxx
   3 | c    | yyy
(2 rows)
=>> SELECT * FROM t1 LEFT JOIN t2 ON t1.num = t2.num;>
 num | name | num | value
-----+------+-----+-------
   1 | a    |   1 | xxx
   2 | b    |     |
   3 | c    |   3 | yyy
(3 rows)
=>> SELECT * FROM t1 LEFT JOIN t2 USING (num);>
 num | name | value
-----+------+-------
   1 | a    | xxx
   2 | b    |
   3 | c    | yyy
(3 rows)
=>> SELECT * FROM t1 RIGHT JOIN t2 ON t1.num = t2.num;>
 num | name | num | value
-----+------+-----+-------
   1 | a    |   1 | xxx
   3 | c    |   3 | yyy
     |      |   5 | zzz
(3 rows)
=>> SELECT * FROM t1 FULL JOIN t2 ON t1.num = t2.num;>
 num | name | num | value
-----+------+-----+-------
   1 | a    |   1 | xxx
   2 | b    |     |
   3 | c    |   3 | yyy
     |      |   5 | zzz
(4 rows)
    
    
     The join condition specified with ON> can also contain
     conditions that do not relate directly to the join.  This can
     prove useful for some queries but needs to be thought out
     carefully.  For example:
=>> SELECT * FROM t1 LEFT JOIN t2 ON t1.num = t2.num AND t2.value = 'xxx';>
 num | name | num | value
-----+------+-----+-------
   1 | a    |   1 | xxx
   2 | b    |     |
   3 | c    |     |
(3 rows)
     Notice that placing the restriction in the WHERE> clause
     produces a different result:
=>> SELECT * FROM t1 LEFT JOIN t2 ON t1.num = t2.num WHERE t2.value = 'xxx';>
 num | name | num | value
-----+------+-----+-------
   1 | a    |   1 | xxx
(1 row)
     This is because a restriction placed in the ON>
     clause is processed before> the join, while 
     a restriction placed in the WHERE> clause is processed
     after> the join.
    
   
   
    Table and Column Aliases
    
     alias
     in the FROM clause
    
    
     label
     alias
    
    
     A temporary name can be given to tables and complex table
     references to be used for references to the derived table in
     the rest of the query.  This is called a table
     alias.
    
    
     To create a table alias, write
FROM table_reference AS alias
     or
FROM table_reference alias
     The AS key word is optional noise.
     alias can be any identifier.
    
    
     A typical application of table aliases is to assign short
     identifiers to long table names to keep the join clauses
     readable.  For example:
SELECT * FROM some_very_long_table_name s JOIN another_fairly_long_name a ON s.id = a.num;
    
    
     The alias becomes the new name of the table reference so far as the
     current query is concerned — it is not allowed to refer to the
     table by the original name elsewhere in the query.  Thus, this is not
     valid:
SELECT * FROM my_table AS m WHERE my_table.a > 5;    -- wrong
    
    
     Table aliases are mainly for notational convenience, but it is
     necessary to use them when joining a table to itself, e.g.:
SELECT * FROM people AS mother JOIN people AS child ON mother.id = child.mother_id;
     Additionally, an alias is required if the table reference is a
     subquery (see ).
    
    
     Parentheses are used to resolve ambiguities.  In the following example,
     the first statement assigns the alias b to the second
     instance of my_table>, but the second statement assigns the
     alias to the result of the join:
SELECT * FROM my_table AS a CROSS JOIN my_table AS b ...
SELECT * FROM (my_table AS a CROSS JOIN my_table) AS b ...
    
    
     Another form of table aliasing gives temporary names to the columns of
     the table, as well as the table itself:
FROM table_reference AS alias ( column1 , column2 , ... )
     If fewer column aliases are specified than the actual table has
     columns, the remaining columns are not renamed.  This syntax is
     especially useful for self-joins or subqueries.
    
    
     When an alias is applied to the output of a JOIN>
     clause, the alias hides the original
     name(s) within the JOIN>.  For example:
SELECT a.* FROM my_table AS a JOIN your_table AS b ON ...
     is valid SQL, but:
SELECT a.* FROM (my_table AS a JOIN your_table AS b ON ...) AS c
     is not valid; the table alias a> is not visible
     outside the alias c>.
    
   
   
    Subqueries
    
     subquery
    
    
     Subqueries specifying a derived table must be enclosed in
     parentheses and must be assigned a table
     alias name.  (See .)  For
     example:
FROM (SELECT * FROM table1) AS alias_name
    
    
     This example is equivalent to FROM table1 AS
     alias_name.  More interesting cases, which cannot be
     reduced to a plain join, arise when the subquery involves
     grouping or aggregation.
    
    
     A subquery can also be a VALUES> list:
FROM (VALUES ('anne', 'smith'), ('bob', 'jones'), ('joe', 'blow'))
     AS names(first, last)
     Again, a table alias is required.  Assigning alias names to the columns
     of the VALUES> list is optional, but is good practice.
     For more information see .
    
   
   
    Table Functions
    table function>>
    
     function>
     in the FROM clause>
    
    
     Table functions are functions that produce a set of rows, made up
     of either base data types (scalar types) or composite data types
     (table rows).  They are used like a table, view, or subquery in
     the FROM> clause of a query. Columns returned by table
     functions can be included in SELECT>,
     JOIN>, or WHERE> clauses in the same manner
     as a table, view, or subquery column.
    
    
     If a table function returns a base data type, the single result
     column name matches the function name. If the function returns a
     composite type, the result columns get the same names as the
     individual attributes of the type.
    
    
     A table function can be aliased in the FROM> clause,
     but it also can be left unaliased. If a function is used in the
     FROM> clause with no alias, the function name is used
     as the resulting table name.
    
    
     Some examples:
CREATE TABLE foo (fooid int, foosubid int, fooname text);
CREATE FUNCTION getfoo(int) RETURNS SETOF foo AS $$
    SELECT * FROM foo WHERE fooid = $1;
$$ LANGUAGE SQL;
SELECT * FROM getfoo(1) AS t1;
SELECT * FROM foo
    WHERE foosubid IN (
                        SELECT foosubid
                        FROM getfoo(foo.fooid) z
                        WHERE z.fooid = foo.fooid
                      );
CREATE VIEW vw_getfoo AS SELECT * FROM getfoo(1);
SELECT * FROM vw_getfoo;
    
    
     In some cases it is useful to define table functions that can
     return different column sets depending on how they are invoked.
     To support this, the table function can be declared as returning
     the pseudotype record>.  When such a function is used in
     a query, the expected row structure must be specified in the
     query itself, so that the system can know how to parse and plan
     the query.  Consider this example:
SELECT *
    FROM dblink('dbname=mydb', 'SELECT proname, prosrc FROM pg_proc')
      AS t1(proname name, prosrc text)
    WHERE proname LIKE 'bytea%';
     The dblink> function executes a remote query (see
     contrib/dblink>).  It is declared to return
     record> since it might be used for any kind of query.
     The actual column set must be specified in the calling query so
     that the parser knows, for example, what *> should
     expand to.
    
   
  
  
   The WHERE Clause
   
    WHERE
   
   
    The syntax of the  is
WHERE search_condition
    where search_condition is any value
    expression (see ) that
    returns a value of type boolean.
   
   
    After the processing of the FROM> clause is done, each
    row of the derived virtual table is checked against the search
    condition.  If the result of the condition is true, the row is
    kept in the output table, otherwise (i.e., if the result is
    false or null) it is discarded.  The search condition typically
    references at least one column of the table generated in the
    FROM> clause; this is not required, but otherwise the
    WHERE> clause will be fairly useless.
   
   
    
     The join condition of an inner join can be written either in
     the WHERE> clause or in the JOIN> clause.
     For example, these table expressions are equivalent:
FROM a, b WHERE a.id = b.id AND b.val > 5
     and:
FROM a INNER JOIN b ON (a.id = b.id) WHERE b.val > 5
     or perhaps even:
FROM a NATURAL JOIN b WHERE b.val > 5
     Which one of these you use is mainly a matter of style.  The
     JOIN> syntax in the FROM> clause is
     probably not as portable to other SQL database management systems,
     even though it is in the SQL standard.  For
     outer joins there is no choice:  they must be done in
     the FROM> clause.  The ON> or USING>
     clause of an outer join is not> equivalent to a
     WHERE> condition, because it results in the addition
     of rows (for unmatched input rows) as well as the removal of rows
     in the final result.
    
   
   
    Here are some examples of WHERE clauses:
SELECT ... FROM fdt WHERE c1 > 5
SELECT ... FROM fdt WHERE c1 IN (1, 2, 3)
SELECT ... FROM fdt WHERE c1 IN (SELECT c1 FROM t2)
SELECT ... FROM fdt WHERE c1 IN (SELECT c3 FROM t2 WHERE c2 = fdt.c1 + 10)
SELECT ... FROM fdt WHERE c1 BETWEEN (SELECT c3 FROM t2 WHERE c2 = fdt.c1 + 10) AND 100
SELECT ... FROM fdt WHERE EXISTS (SELECT c1 FROM t2 WHERE c2 > fdt.c1)
    fdt is the table derived in the
    FROM> clause. Rows that do not meet the search
    condition of the WHERE> clause are eliminated from
    fdt. Notice the use of scalar subqueries as
    value expressions.  Just like any other query, the subqueries can
    employ complex table expressions.  Notice also how
    fdt is referenced in the subqueries.
    Qualifying c1> as fdt.c1> is only necessary
    if c1> is also the name of a column in the derived
    input table of the subquery.  But qualifying the column name adds
    clarity even when it is not needed.  This example shows how the column
    naming scope of an outer query extends into its inner queries.
   
  
  
   The GROUP BY and HAVING Clauses
   
    GROUP BY
   
   
    grouping
   
   
    After passing the WHERE> filter, the derived input
    table might be subject to grouping, using the GROUP BY>
    clause, and elimination of group rows using the HAVING>
    clause.
   
SELECT select_list
    FROM ...
    WHERE ...
    GROUP BY grouping_column_reference , grouping_column_reference...
   
    The  is
    used to group together those rows in a table that have the same
    values in all the columns listed. The order in which the columns
    are listed does not matter.  The effect is to combine each set
    of rows having common values into one group row that
    represents all rows in the group.  This is done to
    eliminate redundancy in the output and/or compute aggregates that
    apply to these groups.  For instance:
=>> SELECT * FROM test1;>
 x | y
---+---
 a | 3
 c | 2
 b | 5
 a | 1
(4 rows)
=>> SELECT x FROM test1 GROUP BY x;>
 x
---
 a
 b
 c
(3 rows)
   
   
    In the second query, we could not have written SELECT *
    FROM test1 GROUP BY x, because there is no single value
    for the column y> that could be associated with each
    group.  The grouped-by columns can be referenced in the select list since
    they have a single value in each group.
   
   
    In general, if a table is grouped, columns that are not
    listed in GROUP BY> cannot be referenced except in aggregate
    expressions.  An example with aggregate expressions is:
=>> SELECT x, sum(y) FROM test1 GROUP BY x;>
 x | sum
---+-----
 a |   4
 b |   5
 c |   2
(3 rows)
    Here sum is an aggregate function that
    computes a single value over the entire group.  More information
    about the available aggregate functions can be found in .
   
   
    
     Grouping without aggregate expressions effectively calculates the
     set of distinct values in a column.  This can also be achieved
     using the DISTINCT> clause (see ).
    
   
   
    Here is another example:  it calculates the total sales for each
    product (rather than the total sales of all products):
SELECT product_id, p.name, (sum(s.units) * p.price) AS sales
    FROM products p LEFT JOIN sales s USING (product_id)
    GROUP BY product_id, p.name, p.price;
    In this example, the columns product_id,
    p.name, and p.price must be
    in the GROUP BY> clause since they are referenced in
    the query select list.  (Depending on how the products
    table is set up, name and price might be fully dependent on the
    product ID, so the additional groupings could theoretically be
    unnecessary, though this is not implemented.)  The column
    s.units> does not have to be in the GROUP
    BY> list since it is only used in an aggregate expression
    (sum(...)), which represents the sales
    of a product.  For each product, the query returns a summary row about
    all sales of the product.
   
   
    In strict SQL, GROUP BY> can only group by columns of
    the source table but PostgreSQL extends
    this to also allow GROUP BY> to group by columns in the
    select list.  Grouping by value expressions instead of simple
    column names is also allowed.
   
   
    HAVING
   
   
    If a table has been grouped using GROUP BY,
    but only certain groups are of interest, the
    HAVING clause can be used, much like a
    WHERE> clause, to eliminate groups from the result.
    The syntax is:
SELECT select_list FROM ... WHERE ... GROUP BY ... HAVING boolean_expression
    Expressions in the HAVING> clause can refer both to
    grouped expressions and to ungrouped expressions (which necessarily
    involve an aggregate function).
   
   
    Example:
=>> SELECT x, sum(y) FROM test1 GROUP BY x HAVING sum(y) > 3;>
 x | sum
---+-----
 a |   4
 b |   5
(2 rows)
=>> SELECT x, sum(y) FROM test1 GROUP BY x HAVING x < 'c';>
 x | sum
---+-----
 a |   4
 b |   5
(2 rows)
   
   
    Again, a more realistic example:
SELECT product_id, p.name, (sum(s.units) * (p.price - p.cost)) AS profit
    FROM products p LEFT JOIN sales s USING (product_id)
    WHERE s.date > CURRENT_DATE - INTERVAL '4 weeks'
    GROUP BY product_id, p.name, p.price, p.cost
    HAVING sum(p.price * s.units) > 5000;
    In the example above, the WHERE> clause is selecting
    rows by a column that is not grouped (the expression is only true for
    sales during the last four weeks), while the HAVING>
    clause restricts the output to groups with total gross sales over
    5000.  Note that the aggregate expressions do not necessarily need
    to be the same in all parts of the query.
   
   
    If a query contains aggregate function calls, but no GROUP BY>
    clause, grouping still occurs: the result is a single group row (or
    perhaps no rows at all, if the single row is then eliminated by
    HAVING>).
    The same is true if it contains a HAVING> clause, even
    without any aggregate function calls or GROUP BY> clause.
   
  
  
   Window Function Processing>
   
    window function
    order of execution>
   
   
    If the query contains any window functions (see
     and
    ), these functions are evaluated
    after any grouping, aggregation, and HAVING> filtering is
    performed.  That is, if the query uses any aggregates, GROUP
    BY>, or HAVING>, then the rows seen by the window functions
    are the group rows instead of the original table rows from
    FROM>/WHERE>.
   
   
    When multiple window functions are used, all the window functions having
    syntactically equivalent PARTITION BY> and ORDER BY>
    clauses in their window definitions are guaranteed to be evaluated in a
    single pass over the data. Therefore they will see the same sort ordering,
    even if the ORDER BY> does not uniquely determine an ordering.
    However, no guarantees are made about the evaluation of functions having
    different PARTITION BY> or ORDER BY> specifications.
    (In such cases a sort step is typically required between the passes of
    window function evaluations, and the sort is not guaranteed to preserve
    ordering of rows that its ORDER BY> sees as equivalent.)
   
   
    Currently, window functions always require presorted data, and so the
    query output will be ordered according to one or another of the window
    functions' PARTITION BY>/ORDER BY> clauses.
    It is not recommendable to rely on this, however.  Use an explicit
    top-level ORDER BY> clause if you want to be sure the
    results are sorted in a particular way.
   
  
 
 
  Select Lists
  
   SELECT
   select list
  
  
   As shown in the previous section,
   the table expression in the SELECT command
   constructs an intermediate virtual table by possibly combining
   tables, views, eliminating rows, grouping, etc.  This table is
   finally passed on to processing by the select list.  The select
   list determines which columns of the
   intermediate table are actually output.
  
  
   Select-List Items
   
    *
   
   
    The simplest kind of select list is * which
    emits all columns that the table expression produces.  Otherwise,
    a select list is a comma-separated list of value expressions (as
    defined in ).  For instance, it
    could be a list of column names:
SELECT a, b, c FROM ...
     The columns names a>, b>, and c>
     are either the actual names of the columns of tables referenced
     in the FROM> clause, or the aliases given to them as
     explained in .  The name
     space available in the select list is the same as in the
     WHERE> clause, unless grouping is used, in which case
     it is the same as in the HAVING> clause.
   
   
    If more than one table has a column of the same name, the table
    name must also be given, as in:
SELECT tbl1.a, tbl2.a, tbl1.b FROM ...
    When working with multiple tables, it can also be useful to ask for
    all the columns of a particular table:
SELECT tbl1.*, tbl2.a FROM ...
    (See also .)
   
   
    If an arbitrary value expression is used in the select list, it
    conceptually adds a new virtual column to the returned table.  The
    value expression is evaluated once for each result row, with
    the row's values substituted for any column references.  But the
    expressions in the select list do not have to reference any
    columns in the table expression of the FROM> clause;
    they can be constant arithmetic expressions, for instance.
   
  
  
   Column Labels
   
    alias
    in the select list
   
   
    The entries in the select list can be assigned names for subsequent
    processing, such as for use in an ORDER BY> clause
    or for display by the client application.  For example:
SELECT a AS value, b + c AS sum FROM ...
   
   
    If no output column name is specified using AS>,
    the system assigns a default column name.  For simple column references,
    this is the name of the referenced column.  For function
    calls, this is the name of the function.  For complex expressions,
    the system will generate a generic name.
   
   
    The AS> keyword is optional, but only if the new column
    name does not match any
    PostgreSQL keyword (see ).  To avoid an accidental match to
    a keyword, you can double-quote the column name.  For example,
    VALUE> is a keyword, so this does not work:
SELECT a value, b + c AS sum FROM ...
    but this does:
SELECT a "value", b + c AS sum FROM ...
    For protection against possible
    future keyword additions, it is recommended that you always either
    write AS or double-quote the output column name.
   
   
    
     The naming of output columns here is different from that done in
     the FROM> clause (see ).  It is possible 
     to rename the same column twice, but the name assigned in
     the select list is the one that will be passed on.
    
   
  
  
   DISTINCT
   
    DISTINCT
   
   
    duplicates
   
   
    After the select list has been processed, the result table can
    optionally be subject to the elimination of duplicate rows.  The
    DISTINCT key word is written directly after
    SELECT to specify this:
SELECT DISTINCT select_list ...
    (Instead of DISTINCT> the key word ALL
    can be used to specify the default behavior of retaining all rows.)
   
   
    null value>in
    DISTINCT>
    Obviously, two rows are considered distinct if they differ in at
    least one column value.  Null values are considered equal in this
    comparison.
   
   
    Alternatively, an arbitrary expression can determine what rows are
    to be considered distinct:
SELECT DISTINCT ON (expression , expression ...) select_list ...
    Here expression is an arbitrary value
    expression that is evaluated for all rows.  A set of rows for
    which all the expressions are equal are considered duplicates, and
    only the first row of the set is kept in the output.  Note that
    the first row
 of a set is unpredictable unless the
    query is sorted on enough columns to guarantee a unique ordering
    of the rows arriving at the DISTINCT> filter.
    (DISTINCT ON> processing occurs after ORDER
    BY> sorting.)
   
   
    The DISTINCT ON> clause is not part of the SQL standard
    and is sometimes considered bad style because of the potentially
    indeterminate nature of its results.  With judicious use of
    GROUP BY> and subqueries in FROM>, this
    construct can be avoided, but it is often the most convenient
    alternative.
   
  
 
 
  Combining Queries
  
   UNION
  
  
   INTERSECT
  
  
   EXCEPT
  
  
   set union
  
  
   set intersection
  
  
   set difference
  
  
   set operation
  
  
   The results of two queries can be combined using the set operations
   union, intersection, and difference.  The syntax is
query1 UNION ALL query2
query1 INTERSECT ALL query2
query1 EXCEPT ALL query2
   query1 and
   query2 are queries that can use any of
   the features discussed up to this point.  Set operations can also
   be nested and chained, for example
query1 UNION query2 UNION query3
   which is executed as:
(query1 UNION query2) UNION query3
  
  
   UNION> effectively appends the result of
   query2 to the result of
   query1 (although there is no guarantee
   that this is the order in which the rows are actually returned).
   Furthermore, it eliminates duplicate rows from its result, in the same
   way as DISTINCT>, unless UNION ALL> is used.
  
  
   INTERSECT> returns all rows that are both in the result
   of query1 and in the result of
   query2.  Duplicate rows are eliminated
   unless INTERSECT ALL> is used.
  
  
   EXCEPT> returns all rows that are in the result of
   query1 but not in the result of
   query2.  (This is sometimes called the
   difference> between two queries.)  Again, duplicates
   are eliminated unless EXCEPT ALL> is used.
  
  
   In order to calculate the union, intersection, or difference of two
   queries, the two queries must be union compatible
,
   which means that they return the same number of columns and
   the corresponding columns have compatible data types, as
   described in .
  
 
 
  Sorting Rows
  
   sorting
  
  
   ORDER BY
  
  
   After a query has produced an output table (after the select list
   has been processed) it can optionally be sorted.  If sorting is not
   chosen, the rows will be returned in an unspecified order.  The actual
   order in that case will depend on the scan and join plan types and
   the order on disk, but it must not be relied on.  A particular
   output ordering can only be guaranteed if the sort step is explicitly
   chosen.
  
  
   The ORDER BY> clause specifies the sort order:
SELECT select_list
    FROM table_expression
    ORDER BY sort_expression1 ASC | DESC NULLS { FIRST | LAST }
             , sort_expression2 ASC | DESC NULLS { FIRST | LAST } ...
   The sort expression(s) can be any expression that would be valid in the
   query's select list.  An example is:
SELECT a, b FROM table1 ORDER BY a + b, c;
   When more than one expression is specified,
   the later values are used to sort rows that are equal according to the
   earlier values.  Each expression can be followed by an optional
   ASC> or DESC> keyword to set the sort direction to
   ascending or descending.  ASC> order is the default.
   Ascending order puts smaller values first, where
   smaller
 is defined in terms of the
   < operator.  Similarly, descending order is
   determined with the > operator.
    
     
      Actually, PostgreSQL> uses the default B-tree
      operator class> for the expression's data type to determine the sort
      ordering for ASC> and DESC>.  Conventionally,
      data types will be set up so that the < and
      > operators correspond to this sort ordering,
      but a user-defined data type's designer could choose to do something
      different.
     
    
  
  
   The NULLS FIRST> and NULLS LAST> options can be
   used to determine whether nulls appear before or after non-null values
   in the sort ordering.  By default, null values sort as if larger than any
   non-null value; that is, NULLS FIRST> is the default for
   DESC> order, and NULLS LAST> otherwise.
  
  
   Note that the ordering options are considered independently for each
   sort column.  For example ORDER BY x, y DESC> means
   ORDER BY x ASC, y DESC>, which is not the same as
   ORDER BY x DESC, y DESC>.
  
  
   A sort_expression> can also be the column label or number
   of an output column, as in:
SELECT a + b AS sum, c FROM table1 ORDER BY sum;
SELECT a, max(b) FROM table1 GROUP BY a ORDER BY 1;
   both of which sort by the first output column.  Note that an output
   column name has to stand alone, that is, it cannot be used in an expression
   — for example, this is not> correct:
SELECT a + b AS sum, c FROM table1 ORDER BY sum + c;          -- wrong
   This restriction is made to reduce ambiguity.  There is still
   ambiguity if an ORDER BY> item is a simple name that
   could match either an output column name or a column from the table
   expression.  The output column is used in such cases.  This would
   only cause confusion if you use AS> to rename an output
   column to match some other table column's name.
  
  
   ORDER BY> can be applied to the result of a
   UNION>, INTERSECT>, or EXCEPT>
   combination, but in this case it is only permitted to sort by
   output column names or numbers, not by expressions.
  
 
 
  LIMIT and OFFSET
  
   LIMIT
  
  
   OFFSET
  
  
   LIMIT> and OFFSET> allow you to retrieve just
   a portion of the rows that are generated by the rest of the query:
SELECT select_list
    FROM table_expression
     ORDER BY ... 
     LIMIT { number | ALL }   OFFSET number 
  
  
   If a limit count is given, no more than that many rows will be
   returned (but possibly less, if the query itself yields less rows).
   LIMIT ALL> is the same as omitting the LIMIT>
   clause.
  
  
   OFFSET> says to skip that many rows before beginning to
   return rows.  OFFSET 0> is the same as omitting the
   OFFSET> clause, and LIMIT NULL> is the same
   as omitting the LIMIT> clause.  If both OFFSET>
   and LIMIT> appear, then OFFSET> rows are
   skipped before starting to count the LIMIT> rows that
   are returned.
  
  
   When using LIMIT>, it is important to use an
   ORDER BY> clause that constrains the result rows into a
   unique order.  Otherwise you will get an unpredictable subset of
   the query's rows. You might be asking for the tenth through
   twentieth rows, but tenth through twentieth in what ordering? The
   ordering is unknown, unless you specified ORDER BY>.
  
  
   The query optimizer takes LIMIT> into account when
   generating query plans, so you are very likely to get different
   plans (yielding different row orders) depending on what you give
   for LIMIT> and OFFSET>.  Thus, using
   different LIMIT>/OFFSET> values to select
   different subsets of a query result will give
   inconsistent results unless you enforce a predictable
   result ordering with ORDER BY>.  This is not a bug; it
   is an inherent consequence of the fact that SQL does not promise to
   deliver the results of a query in any particular order unless
   ORDER BY> is used to constrain the order.
  
  
   The rows skipped by an OFFSET> clause still have to be
   computed inside the server; therefore a large OFFSET>
   might be inefficient.
  
 
 
  VALUES Lists
  
   VALUES
  
  
   VALUES> provides a way to generate a constant table>
   that can be used in a query without having to actually create and populate
   a table on-disk.  The syntax is
VALUES ( expression [, ...] ) [, ...]
   Each parenthesized list of expressions generates a row in the table.
   The lists must all have the same number of elements (i.e., the number
   of columns in the table), and corresponding entries in each list must
   have compatible data types.  The actual data type assigned to each column
   of the result is determined using the same rules as for UNION>
   (see ).
  
  
   As an example:
VALUES (1, 'one'), (2, 'two'), (3, 'three');
   will return a table of two columns and three rows.  It's effectively
   equivalent to:
SELECT 1 AS column1, 'one' AS column2
UNION ALL
SELECT 2, 'two'
UNION ALL
SELECT 3, 'three';
   By default, PostgreSQL assigns the names
   column1>, column2>, etc. to the columns of a
   VALUES> table.  The column names are not specified by the
   SQL standard and different database systems do it differently, so
   it's usually better to override the default names with a table alias
   list.
  
  
   Syntactically, VALUES> followed by expression lists is
   treated as equivalent to:
SELECT select_list FROM table_expression
   and can appear anywhere a SELECT> can.  For example, you can
   use it as part of a UNION>, or attach a
   sort_specification (ORDER BY>,
   LIMIT>, and/or OFFSET>) to it.  VALUES>
   is most commonly used as the data source in an INSERT> command,
   and next most commonly as a subquery.
  
  
   For more information see .
  
 
 
  WITH Queries
  
   WITH
   in SELECT
  
  
   common table expression
   WITH
  
  
   WITH> provides a way to write subqueries for use in a larger
   SELECT> query.  The subqueries can be thought of as defining
   temporary tables that exist just for this query.  One use of this feature
   is to break down complicated queries into simpler parts.  An example is:
WITH regional_sales AS (
        SELECT region, SUM(amount) AS total_sales
        FROM orders
        GROUP BY region
     ), top_regions AS (
        SELECT region
        FROM regional_sales
        WHERE total_sales > (SELECT SUM(total_sales)/10 FROM regional_sales)
     )
SELECT region,
       product,
       SUM(quantity) AS product_units,
       SUM(amount) AS product_sales
FROM orders
WHERE region IN (SELECT region FROM top_regions)
GROUP BY region, product;
   which displays per-product sales totals in only the top sales regions.
   This example could have been written without WITH>,
   but we'd have needed two levels of nested sub-SELECTs.  It's a bit
   easier to follow this way.
  
  
   The optional RECURSIVE> modifier changes WITH>
   from a mere syntactic convenience into a feature that accomplishes
   things not otherwise possible in standard SQL.  Using
   RECURSIVE>, a WITH> query can refer to its own
   output.  A very simple example is this query to sum the integers from 1
   through 100:
WITH RECURSIVE t(n) AS (
    VALUES (1)
  UNION ALL
    SELECT n+1 FROM t WHERE n < 100
)
SELECT sum(n) FROM t;
   The general form of a recursive WITH> query is always a
   non-recursive term>, then UNION> (or
   UNION ALL>), then a
   recursive term>, where only the recursive term can contain
   a reference to the query's own output.  Such a query is executed as
   follows:
  
  
   Recursive Query Evaluation
   
    
     Evaluate the non-recursive term.  For UNION> (but not
     UNION ALL>), discard duplicate rows.  Include all remaining
     rows in the result of the recursive query, and also place them in a
     temporary working table>.
    
   
   
    
     So long as the working table is not empty, repeat these steps:
    
    
     
      
       Evaluate the recursive term, substituting the current contents of
       the working table for the recursive self-reference.
       For UNION> (but not UNION ALL>), discard
       duplicate rows and rows that duplicate any previous result row.
       Include all remaining rows in the result of the recursive query, and
       also place them in a temporary intermediate table>.
      
     
     
      
       Replace the contents of the working table with the contents of the
       intermediate table, then empty the intermediate table.
      
     
    
   
  
  
   
    Strictly speaking, this process is iteration not recursion, but
    RECURSIVE> is the terminology chosen by the SQL standards
    committee.
   
  
  
   In the example above, the working table has just a single row in each step,
   and it takes on the values from 1 through 100 in successive steps.  In
   the 100th step, there is no output because of the WHERE>
   clause, and so the query terminates.
  
  
   Recursive queries are typically used to deal with hierarchical or
   tree-structured data.  A useful example is this query to find all the
   direct and indirect sub-parts of a product, given only a table that
   shows immediate inclusions:
WITH RECURSIVE included_parts(sub_part, part, quantity) AS (
    SELECT sub_part, part, quantity FROM parts WHERE part = 'our_product'
  UNION ALL
    SELECT p.sub_part, p.part, p.quantity
    FROM included_parts pr, parts p
    WHERE p.part = pr.sub_part
  )
SELECT sub_part, SUM(quantity) as total_quantity
FROM included_parts
GROUP BY sub_part
  
  
   When working with recursive queries it is important to be sure that
   the recursive part of the query will eventually return no tuples,
   or else the query will loop indefinitely.  Sometimes, using
   UNION> instead of UNION ALL> can accomplish this
   by discarding rows that duplicate previous output rows.  However, often a
   cycle does not involve output rows that are completely duplicate: it may be
   necessary to check just one or a few fields to see if the same point has
   been reached before.  The standard method for handling such situations is
   to compute an array of the already-visited values.  For example, consider
   the following query that searches a table graph> using a
   link> field:
WITH RECURSIVE search_graph(id, link, data, depth) AS (
        SELECT g.id, g.link, g.data, 1
        FROM graph g
      UNION ALL
        SELECT g.id, g.link, g.data, sg.depth + 1
        FROM graph g, search_graph sg
        WHERE g.id = sg.link
)
SELECT * FROM search_graph;
   This query will loop if the link> relationships contain
   cycles.  Because we require a depth> output, just changing
   UNION ALL> to UNION> would not eliminate the looping.
   Instead we need to recognize whether we have reached the same row again
   while following a particular path of links.  We add two columns
   path> and cycle> to the loop-prone query:
WITH RECURSIVE search_graph(id, link, data, depth, path, cycle) AS (
        SELECT g.id, g.link, g.data, 1,
          ARRAY[g.id],
          false
        FROM graph g
      UNION ALL
        SELECT g.id, g.link, g.data, sg.depth + 1,
          path || g.id,
          g.id = ANY(path)
        FROM graph g, search_graph sg
        WHERE g.id = sg.link AND NOT cycle
)
SELECT * FROM search_graph;
   Aside from preventing cycles, the array value is often useful in its own
   right as representing the path> taken to reach any particular row.
  
  
   In the general case where more than one field needs to be checked to
   recognize a cycle, use an array of rows.  For example, if we needed to
   compare fields f1> and f2>:
WITH RECURSIVE search_graph(id, link, data, depth, path, cycle) AS (
        SELECT g.id, g.link, g.data, 1,
          ARRAY[ROW(g.f1, g.f2)],
          false
        FROM graph g
      UNION ALL
        SELECT g.id, g.link, g.data, sg.depth + 1,
          path || ROW(g.f1, g.f2),
          ROW(g.f1, g.f2) = ANY(path)
        FROM graph g, search_graph sg
        WHERE g.id = sg.link AND NOT cycle
)
SELECT * FROM search_graph;
  
  
   
    Omit the ROW()> syntax in the common case where only one field
    needs to be checked to recognize a cycle.  This allows a simple array
    rather than a composite-type array to be used, gaining efficiency.
   
  
  
   
    The recursive query evaluation algorithm produces its output in
    breadth-first search order.  You can display the results in depth-first
    search order by making the outer query ORDER BY> a
    path> column constructed in this way.
   
  
  
   A helpful trick for testing queries
   when you are not certain if they might loop is to place a LIMIT>
   in the parent query.  For example, this query would loop forever without
   the LIMIT>:
WITH RECURSIVE t(n) AS (
    SELECT 1
  UNION ALL
    SELECT n+1 FROM t
)
SELECT n FROM t LIMIT 100;
   This works because PostgreSQL's implementation
   evaluates only as many rows of a WITH> query as are actually
   fetched by the parent query.  Using this trick in production is not
   recommended, because other systems might work differently.  Also, it
   usually won't work if you make the outer query sort the recursive query's
   results or join them to some other table.
  
  
   A useful property of WITH> queries is that they are evaluated
   only once per execution of the parent query, even if they are referred to
   more than once by the parent query or sibling WITH> queries.
   Thus, expensive calculations that are needed in multiple places can be
   placed within a WITH> query to avoid redundant work.  Another
   possible application is to prevent unwanted multiple evaluations of
   functions with side-effects.
   However, the other side of this coin is that the optimizer is less able to
   push restrictions from the parent query down into a WITH> query
   than an ordinary sub-query.  The WITH> query will generally be
   evaluated as stated, without suppression of rows that the parent query
   might discard afterwards.  (But, as mentioned above, evaluation might stop
   early if the reference(s) to the query demand only a limited number of
   rows.)