SELECT
  7
  SQL - Language Statements
 
 
  SELECT
  TABLE
  WITH
  retrieve rows from a table or view
 
 
  SELECT
 
 
  TABLE command
 
 
  WITH
  in SELECT
 
 
[ WITH [ RECURSIVE ] with_query [, ...] ]
SELECT [ ALL | DISTINCT [ ON ( expression [, ...] ) ] ]
    * | expression [ [ AS ] output_name ] [, ...]
    [ FROM from_item [, ...] ]
    [ WHERE condition ]
    [ GROUP BY expression [, ...] ]
    [ HAVING condition [, ...] ]
    [ WINDOW window_name AS ( window_definition ) [, ...] ]
    [ { UNION | INTERSECT | EXCEPT } [ ALL ] select ]
    [ ORDER BY expression [ ASC | DESC | USING operator ] [ NULLS { FIRST | LAST } ] [, ...] ]
    [ LIMIT { count | ALL } ]
    [ OFFSET start [ ROW | ROWS ] ]
    [ FETCH { FIRST | NEXT } [ count ] { ROW | ROWS } ONLY ]
    [ FOR { UPDATE | SHARE } [ OF table_name [, ...] ] [ NOWAIT ] [...] ]
where from_item can be one of:
    [ ONLY ] table_name [ * ] [ [ AS ] alias [ ( column_alias [, ...] ) ] ]
    ( select ) [ AS ] alias [ ( column_alias [, ...] ) ]
    with_query_name [ [ AS ] alias [ ( column_alias [, ...] ) ] ]
    function_name ( [ argument [, ...] ] ) [ AS ] alias [ ( column_alias [, ...] | column_definition [, ...] ) ]
    function_name ( [ argument [, ...] ] ) AS ( column_definition [, ...] )
    from_item [ NATURAL ] join_type from_item [ ON join_condition | USING ( join_column [, ...] ) ]
and with_query is:
    with_query_name [ ( column_name [, ...] ) ] AS ( select )
TABLE { [ ONLY ] table_name [ * ] | with_query_name }
 
 
  Description
  
   SELECT retrieves rows from zero or more tables.
   The general processing of SELECT is as follows:
   
    
     
      All queries in the WITH list are computed.
      These effectively serve as temporary tables that can be referenced
      in the FROM list.  A WITH query
      that is referenced more than once in FROM is
      computed only once.
      (See  below.)
     
    
    
     
      All elements in the FROM list are computed.
      (Each element in the FROM list is a real or
      virtual table.)  If more than one element is specified in the
      FROM list, they are cross-joined together.
      (See  below.)
     
    
    
     
      If the WHERE clause is specified, all rows
      that do not satisfy the condition are eliminated from the
      output.  (See  below.)
     
    
    
     
      If the GROUP BY clause is specified, the
      output is divided into groups of rows that match on one or more
      values.  If the HAVING clause is present, it
      eliminates groups that do not satisfy the given condition.  (See
       and
       below.)
     
    
    
     
      The actual output rows are computed using the
      SELECT output expressions for each selected
      row.  (See
      
      below.)
     
    
    
     
      Using the operators UNION,
      INTERSECT, and EXCEPT, the
      output of more than one SELECT statement can
      be combined to form a single result set.  The
      UNION operator returns all rows that are in
      one or both of the result sets.  The
      INTERSECT operator returns all rows that are
      strictly in both result sets.  The EXCEPT
      operator returns the rows that are in the first result set but
      not in the second.  In all three cases, duplicate rows are
      eliminated unless ALL is specified. (See
      , , and
       below.)
     
    
    
     
      If the ORDER BY clause is specified, the
      returned rows are sorted in the specified order.  If
      ORDER BY is not given, the rows are returned
      in whatever order the system finds fastest to produce.  (See
       below.)
     
    
    
     
      DISTINCT eliminates duplicate rows from the
      result.  DISTINCT ON eliminates rows that
      match on all the specified expressions.  ALL
      (the default) will return all candidate rows, including
      duplicates.  (See  below.)
     
    
    
     
      If the LIMIT (or FETCH FIRST) or OFFSET
      clause is specified, the SELECT statement
      only returns a subset of the result rows. (See  below.)
     
    
    
     
      If FOR UPDATE or FOR SHARE
      is specified, the
      SELECT statement locks the selected rows
      against concurrent updates.  (See  below.)
     
    
   
  
  
   You must have SELECT privilege on each column used
   in a SELECT> command.  The use of FOR UPDATE
   or FOR SHARE requires
   UPDATE privilege as well (for at least one column
   of each table so selected).
  
 
 
  Parameters
  
   WITH Clause
   
    The WITH clause allows you to specify one or more
    subqueries that can be referenced by name in the primary query.
    The subqueries effectively act as temporary tables or views
    for the duration of the primary query.
   
   
    A name (without schema qualification) must be specified for each
    WITH query.  Optionally, a list of column names
    can be specified; if this is omitted,
    the column names are inferred from the subquery.
   
   
    If RECURSIVE is specified, it allows a
    subquery to reference itself by name.  Such a subquery must have
    the form
non_recursive_term UNION [ ALL ] recursive_term
    where the recursive self-reference must appear on the right-hand
    side of the UNION>.  Only one recursive self-reference
    is permitted per query.
   
   
    Another effect of RECURSIVE is that
    WITH queries need not be ordered: a query
    can reference another one that is later in the list.  (However,
    circular references, or mutual recursion, are not implemented.)
    Without RECURSIVE, WITH queries
    can only reference sibling WITH queries
    that are earlier in the WITH list.
   
   
    A useful property of WITH queries is that they
    are evaluated only once per execution of the primary query,
    even if the primary query refers to them more than once.
   
   
    See  for additional information.
   
  
  
   FROM Clause
   
    The FROM clause specifies one or more source
    tables for the SELECT.  If multiple sources are
    specified, the result is the Cartesian product (cross join) of all
    the sources.  But usually qualification conditions
    are added to restrict the returned rows to a small subset of the
    Cartesian product.
   
   
    The FROM clause can contain the following
    elements:
    
     
      table_name
      
       
        The name (optionally schema-qualified) of an existing table or
        view.  If ONLY> is specified, only that table is
        scanned.  If ONLY> is not specified, the table and
        any descendant tables are scanned.
       
      
     
     
      alias
      
       
        A substitute name for the FROM> item containing the
        alias.  An alias is used for brevity or to eliminate ambiguity
        for self-joins (where the same table is scanned multiple
        times).  When an alias is provided, it completely hides the
        actual name of the table or function; for example given
        FROM foo AS f>, the remainder of the
        SELECT must refer to this FROM>
        item as f> not foo>.  If an alias is
        written, a column alias list can also be written to provide
        substitute names for one or more columns of the table.
       
      
     
     
      select
      
       
        A sub-SELECT can appear in the
        FROM clause.  This acts as though its
        output were created as a temporary table for the duration of
        this single SELECT command.  Note that the
        sub-SELECT must be surrounded by
        parentheses, and an alias must be
        provided for it.  A
         command
        can also be used here.
       
      
     
     
      with_query_name
      
       
        A WITH> query is referenced by writing its name,
        just as though the query's name were a table name.  (In fact,
        the WITH> query hides any real table of the same name
        for the purposes of the primary query.  If necessary, you can
        refer to a real table of the same name by schema-qualifying
        the table's name.)
        An alias can be provided in the same way as for a table.
       
      
     
     
      function_name
      
       
        Function calls can appear in the FROM
        clause.  (This is especially useful for functions that return
        result sets, but any function can be used.)  This acts as
        though its output were created as a temporary table for the
        duration of this single SELECT command. An
        alias can also be used. If an alias is written, a column alias
        list can also be written to provide substitute names for one
        or more attributes of the function's composite return type. If
        the function has been defined as returning the record>
        data type, then an alias or the key word AS> must
        be present, followed by a column definition list in the form
        ( column_name data_type , ... >
        ).  The column definition list must match the actual
        number and types of columns returned by the function.
       
      
     
     
      join_type
      
       
        One of
        
         
          [ INNER ] JOIN
         
         
          LEFT [ OUTER ] JOIN
         
         
          RIGHT [ OUTER ] JOIN
         
         
          FULL [ OUTER ] JOIN
         
         
          CROSS JOIN
         
        
        For the INNER> and OUTER> join types, a
        join condition must be specified, namely exactly one of
        NATURAL>, ON join_condition, or
        USING (join_column [, ...]).
        See below for the meaning.  For CROSS JOIN,
        none of these clauses can appear.
       
       
        A JOIN clause combines two
        FROM> items.  Use parentheses if necessary to
        determine the order of nesting.  In the absence of parentheses,
        JOINs nest left-to-right.  In any case
        JOIN binds more tightly than the commas
        separating FROM> items.
       
       
        CROSS JOIN> and INNER JOIN
        produce a simple Cartesian product, the same result as you get from
        listing the two items at the top level of FROM>,
        but restricted by the join condition (if any).
        CROSS JOIN> is equivalent to INNER JOIN ON
        (TRUE)>, that is, no rows are removed by qualification.
        These join types are just a notational convenience, since they
        do nothing you couldn't do with plain FROM> and
        WHERE>.
       
       
        LEFT OUTER JOIN> returns all rows in the qualified
        Cartesian product (i.e., all combined rows that pass its join
        condition), plus one copy of each row in the left-hand table
        for which there was no right-hand row that passed the join
        condition.  This left-hand row is extended to the full width
        of the joined table by inserting null values for the
        right-hand columns.  Note that only the JOIN>
        clause's own condition is considered while deciding which rows
        have matches.  Outer conditions are applied afterwards.
       
       
        Conversely, RIGHT OUTER JOIN> returns all the
        joined rows, plus one row for each unmatched right-hand row
        (extended with nulls on the left).  This is just a notational
        convenience, since you could convert it to a LEFT
        OUTER JOIN> by switching the left and right inputs.
       
       
        FULL OUTER JOIN> returns all the joined rows, plus
        one row for each unmatched left-hand row (extended with nulls
        on the right), plus one row for each unmatched right-hand row
        (extended with nulls on the left).
       
      
     
     
      ON join_condition
      
       
        join_condition is
        an expression resulting in a value of type
        boolean (similar to a WHERE
        clause) that specifies which rows in a join are considered to
        match.
       
      
     
     
      USING ( join_column [, ...] )
      
       
        A clause of the form USING ( a, b, ... ) is
        shorthand for ON left_table.a = right_table.a AND
        left_table.b = right_table.b ....  Also,
        USING> implies that only one of each pair of
        equivalent columns will be included in the join output, not
        both.
       
      
     
     
      NATURAL
      
       
        NATURAL is shorthand for a
        USING> list that mentions all columns in the two
        tables that have the same names.
       
      
     
    
   
  
  
   WHERE Clause
   
    The optional WHERE clause has the general form
WHERE condition
    where condition is
    any expression that evaluates to a result of type
    boolean.  Any row that does not satisfy this
    condition will be eliminated from the output.  A row satisfies the
    condition if it returns true when the actual row values are
    substituted for any variable references.
   
  
  
   GROUP BY Clause
   
    The optional GROUP BY clause has the general form
GROUP BY expression [, ...]
   
   
    GROUP BY will condense into a single row all
    selected rows that share the same values for the grouped
    expressions.  expression can be an input column
    name, or the name or ordinal number of an output column
    (SELECT list item), or an arbitrary
    expression formed from input-column values.  In case of ambiguity,
    a GROUP BY name will be interpreted as an
    input-column name rather than an output column name.
   
   
    Aggregate functions, if any are used, are computed across all rows
    making up each group, producing a separate value for each group
    (whereas without GROUP BY, an aggregate
    produces a single value computed across all the selected rows).
    When GROUP BY is present, it is not valid for
    the SELECT list expressions to refer to
    ungrouped columns except within aggregate functions, since there
    would be more than one possible value to return for an ungrouped
    column.
   
  
  
   HAVING Clause
   
    The optional HAVING clause has the general form
HAVING condition
    where condition is
    the same as specified for the WHERE clause.
   
   
    HAVING eliminates group rows that do not
    satisfy the condition.  HAVING is different
    from WHERE: WHERE filters
    individual rows before the application of GROUP
    BY, while HAVING filters group rows
    created by GROUP BY.  Each column referenced in
    condition must
    unambiguously reference a grouping column, unless the reference
    appears within an aggregate function.
   
   
    The presence of HAVING turns a query into a grouped
    query even if there is no GROUP BY> clause.  This is the
    same as what happens when the query contains aggregate functions but
    no GROUP BY> clause.  All the selected rows are considered to
    form a single group, and the SELECT list and
    HAVING clause can only reference table columns from
    within aggregate functions.  Such a query will emit a single row if the
    HAVING condition is true, zero rows if it is not true.
   
  
  
   WINDOW Clause
   
    The optional WINDOW clause has the general form
WINDOW window_name AS ( window_definition ) [, ...]
    where window_name is
    a name that can be referenced from subsequent window definitions or
    OVER> clauses, and
    window_definition is
[ existing_window_name ]
[ PARTITION BY expression [, ...] ]
[ ORDER BY expression [ ASC | DESC | USING operator ] [ NULLS { FIRST | LAST } ] [, ...] ]
[ frame_clause ]
   
   
    If an existing_window_name
    is specified it must refer to an earlier entry in the WINDOW>
    list; the new window copies its partitioning clause from that entry,
    as well as its ordering clause if any.  In this case the new window cannot
    specify its own PARTITION BY> clause, and it can specify
    ORDER BY> only if the copied window does not have one.
    The new window always uses its own frame clause; the copied window
    must not specify a frame clause.
   
   
    The elements of the PARTITION BY> list are interpreted in
    much the same fashion as elements of a
    , except that
    they are always simple expressions and never the name or number of an
    output column.
    Another difference is that these expressions can contain aggregate
    function calls, which are not allowed in a regular GROUP BY>
    clause.  They are allowed here because windowing occurs after grouping
    and aggregation.
   
   
    Similarly, the elements of the ORDER BY> list are interpreted
    in much the same fashion as elements of an
    , except that
    the expressions are always taken as simple expressions and never the name
    or number of an output column.
   
   
    The optional frame_clause> defines
    the window frame> for window functions that depend on the
    frame (not all do).  It can be one of
RANGE UNBOUNDED PRECEDING
RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW
RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
ROWS UNBOUNDED PRECEDING
ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW
ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
    The first two are equivalent and are also the default: they set the
    frame to be all rows from the partition start up through the current row's
    last peer in the ORDER BY> ordering (which means all rows if
    there is no ORDER BY>).  The options
    RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING> and
    ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING>
    are also equivalent: they always select all rows in the partition.
    Lastly, ROWS UNBOUNDED PRECEDING> or its verbose equivalent
    ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW> select
    all rows up through the current row (regardless of duplicates).
    Beware that this option can produce implementation-dependent results
    if the ORDER BY> ordering does not order the rows uniquely.
   
   
    The purpose of a WINDOW clause is to specify the
    behavior of window functions> appearing in the query's
     or
    .  These functions
    can reference the WINDOW clause entries by name
    in their OVER> clauses.  A WINDOW clause
    entry does not have to be referenced anywhere, however; if it is not
    used in the query it is simply ignored.  It is possible to use window
    functions without any WINDOW clause at all, since
    a window function call can specify its window definition directly in
    its OVER> clause.  However, the WINDOW
    clause saves typing when the same window definition is needed for more
    than one window function.
   
   
    Window functions are described in detail in
    ,
    , and
    .
   
  
  
   SELECT List
   
    The SELECT list (between the key words
    SELECT> and FROM>) specifies expressions
    that form the output rows of the SELECT
    statement.  The expressions can (and usually do) refer to columns
    computed in the FROM> clause.
   
   
    Just as in a table, every output column of a SELECT
    has a name.  In a simple SELECT this name is just
    used to label the column for display, but when the SELECT>
    is a sub-query of a larger query, the name is seen by the larger query
    as the column name of the virtual table produced by the sub-query.
    To specify the name to use for an output column, write
    AS> output_name
    after the column's expression.  (You can omit AS,
    but only if the desired output name does not match any
    PostgreSQL keyword (see ).  For protection against possible
    future keyword additions, it is recommended that you always either
    write AS or double-quote the output name.)
    If you do not specify a column name, a name is chosen automatically
    by PostgreSQL.  If the column's expression
    is a simple column reference then the chosen name is the same as that
    column's name; in more complex cases a generated name looking like
    ?columnN>? is usually chosen.
   
   
    An output column's name can be used to refer to the column's value in
    ORDER BY> and GROUP BY> clauses, but not in the
    WHERE> or HAVING> clauses; there you must write
    out the expression instead.
   
   
    Instead of an expression, * can be written in
    the output list as a shorthand for all the columns of the selected
    rows.  Also, you can write table_name.* as a
    shorthand for the columns coming from just that table.  In these
    cases it is not possible to specify new names with AS>;
    the output column names will be the same as the table columns' names.
   
  
  
   UNION Clause
   
    The UNION clause has this general form:
select_statement UNION [ ALL ] select_statement
    select_statement is
    any SELECT statement without an ORDER
    BY>, LIMIT>, FOR UPDATE, or
    FOR SHARE clause.
    (ORDER BY> and LIMIT> can be attached to a
    subexpression if it is enclosed in parentheses.  Without
    parentheses, these clauses will be taken to apply to the result of
    the UNION, not to its right-hand input
    expression.)
   
   
    The UNION operator computes the set union of
    the rows returned by the involved SELECT
    statements.  A row is in the set union of two result sets if it
    appears in at least one of the result sets.  The two
    SELECT statements that represent the direct
    operands of the UNION must produce the same
    number of columns, and corresponding columns must be of compatible
    data types.
   
   
    The result of UNION> does not contain any duplicate
    rows unless the ALL> option is specified.
    ALL> prevents elimination of duplicates.  (Therefore,
    UNION ALL> is usually significantly quicker than
    UNION>; use ALL> when you can.)
   
   
    Multiple UNION> operators in the same
    SELECT statement are evaluated left to right,
    unless otherwise indicated by parentheses.
   
   
    Currently, FOR UPDATE> and FOR SHARE> cannot be
    specified either for a UNION> result or for any input of a
    UNION>.
   
  
  
   INTERSECT Clause
   
    The INTERSECT clause has this general form:
select_statement INTERSECT [ ALL ] select_statement
    select_statement is
    any SELECT statement without an ORDER
    BY>, LIMIT>, FOR UPDATE, or
    FOR SHARE clause.
   
   
    The INTERSECT operator computes the set
    intersection of the rows returned by the involved
    SELECT statements.  A row is in the
    intersection of two result sets if it appears in both result sets.
   
   
    The result of INTERSECT does not contain any
    duplicate rows unless the ALL> option is specified.
    With ALL>, a row that has m> duplicates in the
    left table and n> duplicates in the right table will appear
    min(m>,n>) times in the result set.
   
   
    Multiple INTERSECT operators in the same
    SELECT statement are evaluated left to right,
    unless parentheses dictate otherwise.
    INTERSECT binds more tightly than
    UNION.  That is, A UNION B INTERSECT
    C will be read as A UNION (B INTERSECT
    C).
   
   
    Currently, FOR UPDATE> and FOR SHARE> cannot be
    specified either for an INTERSECT> result or for any input of
    an INTERSECT>.
   
  
  
   EXCEPT Clause
   
    The EXCEPT clause has this general form:
select_statement EXCEPT [ ALL ] select_statement
    select_statement is
    any SELECT statement without an ORDER
    BY>, LIMIT>, FOR UPDATE, or
    FOR SHARE clause.
   
   
    The EXCEPT operator computes the set of rows
    that are in the result of the left SELECT
    statement but not in the result of the right one.
   
   
    The result of EXCEPT does not contain any
    duplicate rows unless the ALL> option is specified.
    With ALL>, a row that has m> duplicates in the
    left table and n> duplicates in the right table will appear
    max(m>-n>,0) times in the result set.
   
   
    Multiple EXCEPT operators in the same
    SELECT statement are evaluated left to right,
    unless parentheses dictate otherwise.  EXCEPT> binds at
    the same level as UNION>.
   
   
    Currently, FOR UPDATE> and FOR SHARE> cannot be
    specified either for an EXCEPT> result or for any input of
    an EXCEPT>.
   
  
  
   ORDER BY Clause
   
    The optional ORDER BY clause has this general form:
ORDER BY expression [ ASC | DESC | USING operator ] [ NULLS { FIRST | LAST } ] [, ...]
    The ORDER BY clause causes the result rows to
    be sorted according to the specified expression(s).  If two rows are
    equal according to the leftmost expression, they are compared
    according to the next expression and so on.  If they are equal
    according to all specified expressions, they are returned in
    an implementation-dependent order.
   
   
    Each expression can be the
    name or ordinal number of an output column
    (SELECT list item), or it can be an arbitrary
    expression formed from input-column values.
   
   
    The ordinal number refers to the ordinal (left-to-right) position
    of the output column. This feature makes it possible to define an
    ordering on the basis of a column that does not have a unique
    name.  This is never absolutely necessary because it is always
    possible to assign a name to an output column using the
    AS> clause.
   
   
    It is also possible to use arbitrary expressions in the
    ORDER BY clause, including columns that do not
    appear in the SELECT output list.  Thus the
    following statement is valid:
SELECT name FROM distributors ORDER BY code;
    A limitation of this feature is that an ORDER BY>
    clause applying to the result of a UNION>,
    INTERSECT>, or EXCEPT> clause can only
    specify an output column name or number, not an expression.
   
   
    If an ORDER BY> expression is a simple name that
    matches both an output column name and an input column name,
    ORDER BY> will interpret it as the output column name.
    This is the opposite of the choice that GROUP BY> will
    make in the same situation.  This inconsistency is made to be
    compatible with the SQL standard.
   
   
    Optionally one can add the key word ASC> (ascending) or
    DESC> (descending) after any expression in the
    ORDER BY> clause.  If not specified, ASC> is
    assumed by default.  Alternatively, a specific ordering operator
    name can be specified in the USING> clause.
    An ordering operator must be a less-than or greater-than
    member of some B-tree operator family.
    ASC> is usually equivalent to USING <> and
    DESC> is usually equivalent to USING >>.
    (But the creator of a user-defined data type can define exactly what the
    default sort ordering is, and it might correspond to operators with other
    names.)
   
   
    If NULLS LAST> is specified, null values sort after all
    non-null values; if NULLS FIRST> is specified, null values
    sort before all non-null values.  If neither is specified, the default
    behavior is NULLS LAST> when ASC> is specified
    or implied, and NULLS FIRST> when DESC> is specified
    (thus, the default is to act as though nulls are larger than non-nulls).
    When USING> is specified, the default nulls ordering depends
    on whether the operator is a less-than or greater-than operator.
   
   
    Note that ordering options apply only to the expression they follow;
    for example ORDER BY x, y DESC> does not mean
    the same thing as ORDER BY x DESC, y DESC>.
   
   
    Character-string data is sorted according to the locale-specific
    collation order that was established when the database was created.
   
  
  
   DISTINCT Clause
   
    If DISTINCT> is specified, all duplicate rows are
    removed from the result set (one row is kept from each group of
    duplicates).  ALL> specifies the opposite: all rows are
    kept; that is the default.
   
   
    DISTINCT ON ( expression [, ...] )
    keeps only the first row of each set of rows where the given
    expressions evaluate to equal.  The DISTINCT ON
    expressions are interpreted using the same rules as for
    ORDER BY> (see above).  Note that the first
    row
 of each set is unpredictable unless ORDER
    BY> is used to ensure that the desired row appears first.  For
    example:
SELECT DISTINCT ON (location) location, time, report
    FROM weather_reports
    ORDER BY location, time DESC;
    retrieves the most recent weather report for each location.  But
    if we had not used ORDER BY> to force descending order
    of time values for each location, we'd have gotten a report from
    an unpredictable time for each location.
   
   
    The DISTINCT ON> expression(s) must match the leftmost
    ORDER BY> expression(s).  The ORDER BY> clause
    will normally contain additional expression(s) that determine the
    desired precedence of rows within each DISTINCT ON> group.
   
  
  
   LIMIT Clause
   
    The LIMIT clause consists of two independent
    sub-clauses:
LIMIT { count | ALL }
OFFSET start
    count specifies the
    maximum number of rows to return, while start specifies the number of rows
    to skip before starting to return rows.  When both are specified,
    start rows are skipped
    before starting to count the count rows to be returned.
   
   
    If the count expression
    evaluates to NULL, it is treated as LIMIT ALL>, i.e., no
    limit.  If start evaluates
    to NULL, it is treated the same as OFFSET 0>.
   
   
    SQL:2008 introduced a different syntax to achieve the same thing,
    which PostgreSQL> also supports.  It is:
OFFSET start { ROW | ROWS }
FETCH { FIRST | NEXT } [ count ] { ROW | ROWS } ONLY
    According to the standard, the OFFSET clause must come
    before the FETCH clause if both are present; but
    PostgreSQL> is laxer and allows either order.
    ROW
    and ROWS as well as FIRST
    and NEXT are noise words that don't influence
    the effects of these clauses.  In this syntax, when using expressions
    other than simple constants for start>
    or count, parentheses will be
    necessary in most cases.  If count> is
    omitted in FETCH>, it defaults to 1.
   
   
    When using LIMIT>, it is a good idea 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?  You
    don't know what ordering unless you specify ORDER BY>.
   
   
    The query planner takes LIMIT> into account when
    generating a query plan, so you are very likely to get different
    plans (yielding different row orders) depending on what you use
    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.
   
   
    It is even possible for repeated executions of the same LIMIT>
    query to return different subsets of the rows of a table, if there
    is not an ORDER BY> to enforce selection of a deterministic
    subset.  Again, this is not a bug; determinism of the results is
    simply not guaranteed in such a case.
   
  
  
   FOR UPDATE/FOR SHARE Clause
   
    The FOR UPDATE clause has this form:
FOR UPDATE [ OF table_name [, ...] ] [ NOWAIT ]
   
   
    The closely related FOR SHARE clause has this form:
FOR SHARE [ OF table_name [, ...] ] [ NOWAIT ]
   
   
    FOR UPDATE causes the rows retrieved by the
    SELECT statement to be locked as though for
    update.  This prevents them from being modified or deleted by
    other transactions until the current transaction ends.  That is,
    other transactions that attempt UPDATE,
    DELETE, or SELECT FOR UPDATE
    of these rows will be blocked until the current transaction ends.
    Also, if an UPDATE, DELETE,
    or SELECT FOR UPDATE from another transaction
    has already locked a selected row or rows, SELECT FOR
    UPDATE will wait for the other transaction to complete,
    and will then lock and return the updated row (or no row, if the
    row was deleted).  Within a SERIALIZABLE> transaction,
    however, an error will be thrown if a row to be locked has changed
    since the transaction started.  For further discussion see .
   
   
    FOR SHARE behaves similarly, except that it
    acquires a shared rather than exclusive lock on each retrieved
    row.  A shared lock blocks other transactions from performing
    UPDATE, DELETE, or SELECT
    FOR UPDATE on these rows, but it does not prevent them
    from performing SELECT FOR SHARE.
   
   
    To prevent the operation from waiting for other transactions to commit,
    use the NOWAIT> option.  With NOWAIT>, the statement
    reports an error, rather than waiting, if a selected row
    cannot be locked immediately.  Note that NOWAIT> applies only
    to the row-level lock(s) — the required ROW SHARE
    table-level lock is still taken in the ordinary way (see
    ).  You can use
    
    with the NOWAIT> option first,
    if you need to acquire the table-level lock without waiting.
   
   
    If specific tables are named in FOR UPDATE
    or FOR SHARE,
    then only rows coming from those tables are locked; any other
    tables used in the SELECT are simply read as
    usual.  A FOR UPDATE or FOR SHARE
    clause without a table list affects all tables used in the statement.
    If FOR UPDATE or FOR SHARE is
    applied to a view or sub-query, it affects all tables used in
    the view or sub-query.
    However, FOR UPDATE/FOR SHARE
    do not apply to WITH> queries referenced by the primary query.
    If you want row locking to occur within a WITH> query, specify
    FOR UPDATE or FOR SHARE within the
    WITH> query.
   
   
    Multiple FOR UPDATE and FOR SHARE
    clauses can be written if it is necessary to specify different locking
    behavior for different tables.  If the same table is mentioned (or
    implicitly affected) by both FOR UPDATE and
    FOR SHARE clauses, then it is processed as
    FOR UPDATE.  Similarly, a table is processed
    as NOWAIT> if that is specified in any of the clauses
    affecting it.
   
   
    FOR UPDATE and FOR SHARE cannot be
    used in contexts where returned rows cannot be clearly identified with
    individual table rows; for example they cannot be used with aggregation.
   
   
    When FOR UPDATE or FOR SHARE
    appears at the top level of a SELECT> query, the rows that
    are locked are exactly those that are returned by the query; in the
    case of a join query, the rows locked are those that contribute to
    returned join rows.  In addition, rows that satisfied the query
    conditions as of the query snapshot will be locked, although they
    will not be returned if they have since been updated to not satisfy
    the query conditions.  If a LIMIT> is used, locking stops
    once enough rows have been returned to satisfy the limit (but note that
    rows skipped over by OFFSET> will get locked).  Similarly,
    if FOR UPDATE or FOR SHARE
    is used in a cursor's query, only rows actually fetched or stepped past
    by the cursor will be locked.
   
   
    When FOR UPDATE or FOR SHARE
    appears in a sub-SELECT>, the rows locked are those
    returned to the outer query by the sub-query.  This might involve
    fewer rows than inspection of the sub-query alone would suggest,
    since conditions from the outer query might be used to optimize
    execution of the sub-query.  For example,
SELECT * FROM (SELECT * FROM mytable FOR UPDATE) ss WHERE col1 = 5;
    will lock only rows having col1 = 5>, even though that
    condition is not textually within the sub-query.
   
  
   
    Avoid locking a row and then modifying it within a later savepoint or
    PL/pgSQL exception block.  A subsequent
    rollback would cause the lock to be lost.  For example:
BEGIN;
SELECT * FROM mytable WHERE key = 1 FOR UPDATE;
SAVEPOINT s;
UPDATE mytable SET ... WHERE key = 1;
ROLLBACK TO s;
    After the ROLLBACK>, the row is effectively unlocked, rather
    than returned to its pre-savepoint state of being locked but not modified.
    This hazard occurs if a row locked in the current transaction is updated
    or deleted, or if a shared lock is upgraded to exclusive: in all these
    cases, the former lock state is forgotten.  If the transaction is then
    rolled back to a state between the original locking command and the
    subsequent change, the row will appear not to be locked at all.  This is
    an implementation deficiency which will be addressed in a future release
    of PostgreSQL.
   
  
  
   
    It is possible for a SELECT> command using ORDER
    BY and FOR UPDATE/SHARE to return rows out of
    order.  This is because ORDER BY> is applied first.
    The command sorts the result, but might then block trying to obtain a lock
    on one or more of the rows.  Once the SELECT> unblocks, some
    of the ordering column values might have been modified, leading to those
    rows appearing to be out of order (though they are in order in terms
    of the original column values).  This can be worked around at need by
    placing the FOR UPDATE/SHARE clause in a sub-query,
    for example
SELECT * FROM (SELECT * FROM mytable FOR UPDATE) ss ORDER BY column1;
    Note that this will result in locking all rows of mytable>,
    whereas FOR UPDATE> at the top level would lock only the
    actually returned rows.  This can make for a significant performance
    difference, particularly if the ORDER BY> is combined with
    LIMIT> or other restrictions.  So this technique is recommended
    only if concurrent updates of the ordering columns are expected and a
    strictly sorted result is required.
   
  
  
  
   TABLE Command
   
    The command
TABLE name
    is completely equivalent to
SELECT * FROM name
    It can be used as a top-level command or as a space-saving syntax
    variant in parts of complex queries.
   
  
 
 
  Examples
  
   To join the table films with the table
   distributors:
SELECT f.title, f.did, d.name, f.date_prod, f.kind
    FROM distributors d, films f
    WHERE f.did = d.did
       title       | did |     name     | date_prod  |   kind
-------------------+-----+--------------+------------+----------
 The Third Man     | 101 | British Lion | 1949-12-23 | Drama
 The African Queen | 101 | British Lion | 1951-08-11 | Romantic
 ...
  
  
   To sum the column len of all films and group
   the results by kind:
SELECT kind, sum(len) AS total FROM films GROUP BY kind;
   kind   | total
----------+-------
 Action   | 07:34
 Comedy   | 02:58
 Drama    | 14:28
 Musical  | 06:42
 Romantic | 04:38
  
  
   To sum the column len of all films, group
   the results by kind and show those group totals
   that are less than 5 hours:
SELECT kind, sum(len) AS total
    FROM films
    GROUP BY kind
    HAVING sum(len) < interval '5 hours';
   kind   | total
----------+-------
 Comedy   | 02:58
 Romantic | 04:38
  
  
   The following two examples are identical ways of sorting the individual
   results according to the contents of the second column
   (name):
SELECT * FROM distributors ORDER BY name;
SELECT * FROM distributors ORDER BY 2;
 did |       name
-----+------------------
 109 | 20th Century Fox
 110 | Bavaria Atelier
 101 | British Lion
 107 | Columbia
 102 | Jean Luc Godard
 113 | Luso films
 104 | Mosfilm
 103 | Paramount
 106 | Toho
 105 | United Artists
 111 | Walt Disney
 112 | Warner Bros.
 108 | Westward
  
  
   The next example shows how to obtain the union of the tables
   distributors and
   actors, restricting the results to those that begin
   with the letter W in each table.  Only distinct rows are wanted, so the
   key word ALL is omitted.
distributors:               actors:
 did |     name              id |     name
-----+--------------        ----+----------------
 108 | Westward               1 | Woody Allen
 111 | Walt Disney            2 | Warren Beatty
 112 | Warner Bros.           3 | Walter Matthau
 ...                         ...
SELECT distributors.name
    FROM distributors
    WHERE distributors.name LIKE 'W%'
UNION
SELECT actors.name
    FROM actors
    WHERE actors.name LIKE 'W%';
      name
----------------
 Walt Disney
 Walter Matthau
 Warner Bros.
 Warren Beatty
 Westward
 Woody Allen
  
  
   This example shows how to use a function in the FROM>
   clause, both with and without a column definition list:
CREATE FUNCTION distributors(int) RETURNS SETOF distributors AS $$
    SELECT * FROM distributors WHERE did = $1;
$$ LANGUAGE SQL;
SELECT * FROM distributors(111);
 did |    name
-----+-------------
 111 | Walt Disney
CREATE FUNCTION distributors_2(int) RETURNS SETOF record AS $$
    SELECT * FROM distributors WHERE did = $1;
$$ LANGUAGE SQL;
SELECT * FROM distributors_2(111) AS (f1 int, f2 text);
 f1  |     f2
-----+-------------
 111 | Walt Disney
  
  
   This example shows how to use a simple WITH> clause:
WITH t AS (
    SELECT random() as x FROM generate_series(1, 3)
  )
SELECT * FROM t
UNION ALL
SELECT * FROM t
         x          
--------------------
  0.534150459803641
  0.520092216785997
 0.0735620250925422
  0.534150459803641
  0.520092216785997
 0.0735620250925422
   Notice that the WITH> query was evaluated only once,
   so that we got two sets of the same three random values.
  
  
   This example uses WITH RECURSIVE to find all
   subordinates (direct or indirect) of the employee Mary, and their
   level of indirectness, from a table that shows only direct
   subordinates:
WITH RECURSIVE employee_recursive(distance, employee_name, manager_name) AS (
    SELECT 1, employee_name, manager_name
    FROM employee
    WHERE manager_name = 'Mary'
  UNION ALL
    SELECT er.distance + 1, e.employee_name, e.manager_name
    FROM employee_recursive er, employee e
    WHERE er.employee_name = e.manager_name
  )
SELECT distance, employee_name FROM employee_recursive;
   Notice the typical form of recursive queries:
   an initial condition, followed by UNION,
   followed by the recursive part of the query. Be sure that the
   recursive part of the query will eventually return no tuples, or
   else the query will loop indefinitely.  (See 
   for more examples.)
  
 
 
  Compatibility
  
   Of course, the SELECT statement is compatible
   with the SQL standard.  But there are some extensions and some
   missing features.
  
  
   Omitted FROM Clauses
   
    PostgreSQL allows one to omit the
    FROM clause.  It has a straightforward use to
    compute the results of simple expressions:
SELECT 2+2;
 ?column?
----------
        4
    Some other SQL databases cannot do this except
    by introducing a dummy one-row table from which to do the
    SELECT.
   
   
    Note that if a FROM clause is not specified,
    the query cannot reference any database tables. For example, the
    following query is invalid:
SELECT distributors.* WHERE distributors.name = 'Westward';
    PostgreSQL releases prior to
    8.1 would accept queries of this form, and add an implicit entry
    to the query's FROM clause for each table
    referenced by the query. This is no longer allowed.
   
  
  
   Omitting the AS Key Word
   
    In the SQL standard, the optional key word AS> can be
    omitted before an output column name whenever the new column name
    is a valid column name (that is, not the same as any reserved
    keyword).  PostgreSQL is slightly more
    restrictive: AS> is required if the new column name
    matches any keyword at all, reserved or not.  Recommended practice is
    to use AS> or double-quote output column names, to prevent
    any possible conflict against future keyword additions.
   
   
    In FROM items, both the standard and
    PostgreSQL allow AS> to
    be omitted before an alias that is an unreserved keyword.  But
    this is impractical for output column names, because of syntactic
    ambiguities.
   
  
  
   ONLY and Parentheses
   
    The SQL standard requires parentheses around the table name
    after ONLY, as in SELECT * FROM ONLY
    (tab1), ONLY (tab2) WHERE ....  PostgreSQL supports that
    as well, but the parentheses are optional.  (This point applies
    equally to all SQL commands supporting the ONLY
    option.)
   
  
  
   Namespace Available to GROUP BY and ORDER BY
   
    In the SQL-92 standard, an ORDER BY clause can
    only use output column names or numbers, while a GROUP
    BY clause can only use expressions based on input column
    names.  PostgreSQL extends each of
    these clauses to allow the other choice as well (but it uses the
    standard's interpretation if there is ambiguity).
    PostgreSQL also allows both clauses to
    specify arbitrary expressions.  Note that names appearing in an
    expression will always be taken as input-column names, not as
    output-column names.
   
   
    SQL:1999 and later use a slightly different definition which is not
    entirely upward compatible with SQL-92.
    In most cases, however, PostgreSQL
    will interpret an ORDER BY or GROUP
    BY expression the same way SQL:1999 does.
   
  
  
   WINDOW Clause Restrictions
   
    The SQL standard provides additional options for the window
    frame_clause>.
    PostgreSQL currently supports only the
    options listed above.
   
  
  
   LIMIT and OFFSET
   
    The clauses LIMIT and OFFSET
    are PostgreSQL-specific syntax, also
    used by MySQL.  The SQL:2008 standard
    has introduced the clauses OFFSET ... FETCH {FIRST|NEXT}
    ... for the same functionality, as shown above
    in .  This
    syntax is also used by IBM DB2.
    (Applications written for Oracle
    frequently use a workaround involving the automatically
    generated rownum column, which is not available in
    PostgreSQL, to implement the effects of these clauses.)
   
  
  
   FOR UPDATE> and FOR SHARE>
   
    Although FOR UPDATE> appears in the SQL standard, the
    standard allows it only as an option of DECLARE CURSOR>.
    PostgreSQL allows it in any SELECT>
    query as well as in sub-SELECT>s, but this is an extension.
    The FOR SHARE> variant, and the NOWAIT> option,
    do not appear in the standard.
   
  
  
   Nonstandard Clauses
   
    The clause DISTINCT ON is not defined in the
    SQL standard.