SQL Syntax A description of the general syntax of SQL. Lexical Structure SQL input consists of a sequence of commands. A command is composed of a sequence of tokens, terminated by a semicolon (;). The end of the input stream also terminates a command. Which tokens are valid depends on the syntax of the particular command. A token can be a key word, an identifier, a quoted identifier, a literal (or constant), or a special character symbol. Tokens are normally separated by whitespace (space, tab, newline), but need not be if there is no ambiguity (which is generally only the case if a special character is adjacent to some other token type). Additionally, comments can occur in SQL input. They are not tokens, they are effectively equivalent to whitespace. For example, the following is (syntactically) valid SQL input: SELECT * FROM MY_TABLE; UPDATE MY_TABLE SET A = 5; INSERT INTO MY_TABLE VALUES (3, 'hi there'); This is a sequence of three commands, one per line (although this is not required; more than one command can be on a line, and commands can be usefully split across lines). The SQL syntax is not very consistent regarding what tokens identify commands and which are operands or parameters. The first few tokens are generally the command name, so in the above example we would usually speak of a SELECT, an UPDATE, and an INSERT command. But for instance the UPDATE command always requires a SET token to appear in a certain position, and this particular variation of INSERT also requires a VALUES in order to be complete. The precise syntax rules for each command are described in the Reference Manual. Identifiers and Key Words Tokens such as SELECT, UPDATE, or VALUES in the example above are examples of key words, that is, words that have a fixed meaning in the SQL language. The tokens MY_TABLE and A are examples of identifiers. They identify names of tables, columns, or other database objects, depending on the command they are used in. Therefore they are sometimes simply called names. Key words and identifiers have the same lexical structure, meaning that one cannot know whether a token is an identifier or a key word without knowing the language. A complete list of key words can be found in . SQL identifiers and key words must begin with a letter (a-z) or underscore (_). Subsequent characters in an identifier or key word can be letters, digits (0-9), or underscores, although the SQL standard will not define a key word that contains digits or starts or ends with an underscore. The system uses no more than NAMEDATALEN-1 characters of an identifier; longer names can be written in commands, but they will be truncated. By default, NAMEDATALEN is 32 so the maximum identifier length is 31 (but at the time the system is built, NAMEDATALEN can be changed in src/include/postgres_ext.h). Identifier and key word names are case insensitive. Therefore UPDATE MY_TABLE SET A = 5; can equivalently be written as uPDaTE my_TabLE SeT a = 5; A good convention to adopt is perhaps to write key words in upper case and names in lower case, e.g., UPDATE my_table SET a = 5; There is a second kind of identifier: the delimited identifier or quoted identifier. It is formed by enclosing an arbitrary sequence of characters in double-quotes ("). A delimited identifier is always an identifier, never a key word. So "select" could be used to refer to a column or table named select, whereas an unquoted select would be taken as part of a command and would therefore provoke a parse error when used where a table or column name is expected. The example can be written with quoted identifiers like so: UPDATE "my_table" SET "a" = 5; Quoted identifiers can contain any character other than a double quote itself. This allows constructing table or column names that would otherwise not be possible, such as ones containing spaces or ampersands. The length limitation still applies. Quoting an identifier also makes it case-sensitive, whereas unquoted names are always folded to lower case. For example, the identifiers FOO, foo and "foo" are considered the same by Postgres, but "Foo" and "FOO" are different from these three and each other. This is incompatible with SQL, where unquoted names are folded to upper case. Thus, foo is equivalent to "FOO". If you want to write portable applications you are advised to always quote a particular name or never quote it. Constants There are four kinds of implicitly typed constants in Postgres: strings, bit strings, integers, and floating point numbers. Constants can also be specified with explicit types, which can enable more accurate representation and more efficient handling by the system. The implicit constants are described below; explicit constants are discussed afterwards. String Constants A string constant in SQL is an arbitrary sequence of characters bounded by single quotes ('), e.g., 'This is a string'. SQL allows single quotes to be embedded in strings by typing two adjacent single quotes (e.g., 'Dianne''s horse'). In Postgres single quotes may alternatively be escaped with a backslash (\, e.g., 'Dianne\'s horse'). C-style backslash escapes are also available: \b is a backspace, \f is a form feed, \n is a newline, \r is a carriage return, \t is a tab, and \xxx, where xxx is an octal number, is the character with the corresponding ASCII code. Any other character following a backslash is taken literally. Thus, to include a backslash in a string constant, type two backslashes. The character with the code zero cannot be in a string constant. Two string constants that are only separated by whitespace with at least one newline are concatenated and effectively treated as if the string had been written in one constant. For example: SELECT 'foo' 'bar'; is equivalent to SELECT 'foobar'; but SELECT 'foo' 'bar'; is not valid syntax. Bit String Constants Bit string constants look like string constants with a B (upper or lower case) immediately before the opening quote (no intervening whitespace), e.g., B'1001'. The only characters allowed within bit string constants are 0 and 1. Bit strings constants can be continued across lines in the same way as regular string constants. Integer Constants Integer constants in SQL are sequences of decimal digits (0 though 9) with no decimal point. The range of legal values depends on which integer data type is used, but the plain integer type accepts values ranging from -2147483648 to +2147483647. (The optional plus or minus sign is actually a separate unary operator and not part of the integer constant.) Floating Point Constants Floating point constants are accepted in these general forms: digits.digitse+-digits digits.digitse+-digits digitse+-digits where digits is one or more decimal digits. At least one digit must be before or after the decimal point and after the e if you use that option. Thus, a floating point constant is distinguished from an integer constant by the presence of either the decimal point or the exponent clause (or both). There must not be a space or other characters embedded in the constant. These are some examples of valid floating point constants: 3.5 4. .001 5e2 1.925e-3 Floating point constants are of type DOUBLE PRECISION. REAL can be specified explicitly by using SQL string notation or Postgres type notation: REAL '1.23' -- string style '1.23'::REAL -- Postgres (historical) style Constants of Other Types A constant of an arbitrary type can be entered using any one of the following notations: type 'string' 'string'::type CAST ( 'string' AS type ) The value inside the string is passed to the input conversion routine for the type called type. The result is a constant of the indicated type. The explicit type cast may be omitted if there is no ambiguity as to the type the constant must be (for example, when it is passed as an argument to a non-overloaded function), in which case it is automatically coerced. It is also possible to specify a type coercion using a function-like syntax: typename ( value ) although this only works for types whose names are also valid as function names. (For example, double precision can't be used this way --- but the equivalent float8 can.) The ::, CAST(), and function-call syntaxes can also be used to specify the type of arbitrary expressions, but the form type 'string' can only be used to specify the type of a literal constant. Array constants The general format of an array constant is the following: '{ val1 delim val2 delim ... }' where delim is the delimiter character for the type, as recorded in its pg_type entry. (For all built-in types, this is the comma character ",".) Each val is either a constant of the array element type, or a sub-array. An example of an array constant is '{{1,2,3},{4,5,6},{7,8,9}}' This constant is a two-dimensional, 3 by 3 array consisting of three sub-arrays of integers. Individual array elements can be placed between double-quote marks (") to avoid ambiguity problems with respect to white space. Without quote marks, the array-value parser will skip leading white space. (Array constants are actually only a special case of the generic type constants discussed in the previous section. The constant is initially treated as a string and passed to the array input conversion routine. An explicit type specification might be necessary.) Operators An operator is a sequence of up to NAMEDATALEN-1 (31 by default) characters from the following list: + - * / < > = ~ ! @ # % ^ & | ` ? $ There are a few restrictions on operator names, however: "$" (dollar) cannot be a single-character operator, although it can be part of a multi-character operator name. -- and /* cannot appear anywhere in an operator name, since they will be taken as the start of a comment. A multi-character operator name cannot end in "+" or "-", unless the name also contains at least one of these characters: ~ ! @ # % ^ & | ` ? $ For example, @- is an allowed operator name, but *- is not. This restriction allows Postgres to parse SQL-compliant queries without requiring spaces between tokens. When working with non-SQL-standard operator names, you will usually need to separate adjacent operators with spaces to avoid ambiguity. For example, if you have defined a left-unary operator named "@", you cannot write X*@Y; you must write X* @Y to ensure that Postgres reads it as two operator names not one. Special Characters Some characters that are not alphanumeric have a special meaning that is different from being an operator. Details on the usage can be found at the location where the respective syntax element is described. This section only exists to advise the existence and summarize the purposes of these characters. A dollar sign ($) followed by digits is used to represent the positional parameters in the body of a function definition. In other contexts the dollar sign may be part of an operator name. Parentheses (()) have their usual meaning to group expressions and enforce precedence. In some cases parentheses are required as part of the fixed syntax of a particular SQL command. Brackets ([]) are used to select the elements of an array. See for more information on arrays. Commas (,) are used in some syntactical constructs to separate the elements of a list. The semicolon (;) terminates an SQL command. It cannot appear anywhere within a command, except when quoted as a string constant or identifier. The colon (:) is used to select slices from arrays. (See .) In certain SQL dialects (such as Embedded SQL), the colon is used to prefix variable names. The asterisk (*) has a special meaning when used in the SELECT command or with the COUNT aggregate function. The period (.) is used in floating point constants, and to separate table and column names. Comments A comment is an arbitrary sequence of characters beginning with double dashes and extending to the end of the line, e.g.: -- This is a standard SQL92 comment Alternatively, C-style block comments can be used: /* multi-line comment * with nesting: /* nested block comment */ */ where the comment begins with /* and extends to the matching occurrence of */. These block comments nest, as specified in SQL99 but unlike C, so that one can comment out larger blocks of code that may contain existing block comments. A comment is removed from the input stream before further syntax analysis and is effectively replaced by whitespace. Columns A column is either a user-defined column of a given table or one of the following system-defined columns: oid The unique identifier (object ID) of a row. This is a serial number that is added by Postgres to all rows automatically. OIDs are not reused and are 32-bit quantities. tableoid The OID of the table containing this row. This attribute is particularly handy for queries that select from inheritance hierarchies, since without it, it's difficult to tell which individual table a row came from. The tableoid can be joined against the OID attribute of pg_class to obtain the table name. xmin The identity (transaction ID) of the inserting transaction for this tuple. (Note: a tuple is an individual state of a row; each UPDATE of a row creates a new tuple for the same logical row.) cmin The command identifier (starting at zero) within the inserting transaction. xmax The identity (transaction ID) of the deleting transaction, or zero for an undeleted tuple. In practice, this is never nonzero for a visible tuple. cmax The command identifier within the deleting transaction, or zero. Again, this is never nonzero for a visible tuple. ctid The tuple ID of the tuple within its table. This is a pair (block number, tuple index within block) that identifies the physical location of the tuple. Note that although the ctid can be used to locate the tuple very quickly, a row's ctid will change each time it is updated or moved by VACUUM. Therefore ctid is useless as a long-term row identifier. The OID, or even better a user-defined serial number, should be used to identify logical rows. For further information on the system attributes consult . Transaction and command identifiers are 32 bit quantities. Value Expressions Value expressions are used in a variety of syntactic contexts, such as in the target list of the SELECT command, as new column values in INSERT or UPDATE, or in search conditions in a number of commands. The result of a value expression is sometimes called a scalar, to distinguish it from the result of a table expression (which is a table). Value expressions are therefore also called scalar expressions (or even simply expressions). The expression syntax allows the calculation of values from primitive parts using arithmetic, logical, set, and other operations. A value expression is one of the following: A constant or literal value; see . A column reference An operator invocation: expression operator expression (binary infix operator) expression operator (unary postfix operator) operator expression (unary prefix operator) where operator follows the syntax rules of or is one of the tokens AND, OR, and NOT. What particular operators exist and whether they are unary or binary depends on what operators have been defined by the system or the user. describes the built-in operators. ( expression ) Parentheses are used to group subexpressions and override precedence. A positional parameter reference, in the body of a function declaration. A function call An aggregate expression A scalar subquery. This is an ordinary SELECT in parenthesis that returns exactly one row with one column. It is an error to use a subquery that returns more than one row or more than one column in the context of a value expression. In addition to this list, there are a number of contructs that can be classified as an expression but do not follow any general syntax rules. These generally have the semantics of a function or operator and are explained in the appropriate location in . An example is the IS NULL clause. We have already discussed constants in . The following sections discuss the remaining options. Column References A column can be referenced in the form: corelation.columnname `['subscript`]' corelation is either the name of a table, an alias for a table defined by means of a FROM clause, or the keyword NEW or OLD. (NEW and OLD can only appear in the action portion of a rule, while other corelation names can be used in any SQL statement.) The corelation name can be omitted if the column name is unique across all the tables being used in the current query. If column is of an array type, then the optional subscript selects a specific element in the array. If no subscript is provided, then the whole array is selected. Refer to the description of the particular commands in the PostgreSQL Reference Manual for the allowed syntax in each case. Positional Parameters A positional parameter reference is used to indicate a parameter in an SQL function. Typically this is used in SQL function definition statements. The form of a parameter is: $number For example, consider the definition of a function, dept, as CREATE FUNCTION dept (text) RETURNS dept AS 'select * from dept where name = $1' LANGUAGE 'sql'; Here the $1 will be replaced by the first function argument when the function is invoked. Function Calls The syntax for a function call is the name of a legal function (subject to the syntax rules for identifiers of , followed by its argument list enclosed in parentheses: function (expression , expression ... ) For example, the following computes the square root of 2: sqrt(2) The list of built-in functions is in . Other functions may be added by the user. Aggregate Expressions An aggregate expression represents the application of an aggregate function across the rows selected by a query. An aggregate function reduces multiple inputs to a single output value, such as the sum or average of the inputs. The syntax of an aggregate expression is one of the following: aggregate_name (expression) aggregate_name (ALL expression) aggregate_name (DISTINCT expression) aggregate_name ( * ) where aggregate_name is a previously defined aggregate, and expression is any expression that does not itself contain an aggregate expression. The first form of aggregate expression invokes the aggregate across all input rows for which the given expression yields a non-NULL value. The second form is the same as the first, since ALL is the default. The third form invokes the aggregate for all distinct non-NULL values of the expression found in the input rows. The last form invokes the aggregate once for each input row regardless of NULL or non-NULL values; since no particular input value is specified, it is generally only useful for the count() aggregate function. For example, count(*) yields the total number of input rows; count(f1) yields the number of input rows in which f1 is non-NULL; count(distinct f1) yields the number of distinct non-NULL values of f1. The predefined aggregate functions are described in . Lexical Precedence The precedence and associativity of the operators is hard-wired into the parser. Most operators have the same precedence and are left-associative. This may lead to non-intuitive behavior; for example the boolean operators "<" and ">" have a different precedence than the boolean operators "<=" and ">=". Also, you will sometimes need to add parentheses when using combinations of binary and unary operators. For instance SELECT 5 & ~ 6; will be parsed as SELECT (5 &) ~ 6; because the parser has no idea that & is defined as a binary operator. This is the price one pays for extensibility. Operator Precedence (decreasing) OperatorElement Associativity Description :: left Postgres-style typecast [ ] left array element selection . left table/column name separator - right unary minus ^ left exponentiation * / % left multiplication, division, modulo + - left addition, subtraction IS test for TRUE, FALSE, NULL ISNULL test for NULL NOTNULL test for NOT NULL (any other) left all other native and user-defined operators IN set membership BETWEEN containment OVERLAPS time interval overlap LIKE ILIKE string pattern matching < > less than, greater than = right equality, assignment NOT right logical negation AND left logical conjunction OR left logical disjunction
Note that the operator precedence rules also apply to user-defined operators that have the same names as the built-in operators mentioned above. For example, if you define a + operator for some custom data type it will have the same precedence as the built-in + operator, no matter what yours does.
Table Expressions A table expression specifies 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 general syntax of the SELECT command is SELECT select_list table_expression The select_list is a comma separated list of value expressions as defined in that specify the derived columns of the query output table. Column names in the derived table that is the result of the table_expression can be used in the value expressions of the select_list. The 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. The final transformed table that is derived provides the input rows used to derive output rows as specified by the select list of derived column value expressions. FROM clause The FROM clause 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 may be a table name 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 derived table that may then be subject to transformations by the WHERE, GROUP BY, and HAVING clauses and is finally the result of the overall table expression. If a table reference is a simple table name and it is the supertable in a table inheritance hierarchy, rows of the table include rows from all of its subtable successors unless the keyword ONLY precedes the table name. Joined Tables 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, NATURAL, and CROSS JOIN are supported. Join Types CROSS JOIN T1 CROSS JOIN T2 For each combination of rows from T1 and T2 the derived table will contain a row consisting of all columns in T1 followed by all columns in T2. If the tables have have N and M rows respectively, the joined table will have N * M rows. A cross join is essentially an INNER JOIN ON TRUE. FROM T1 CROSS JOIN T2 is equivalent to FROM T1, T2. Qualified JOINs T1 { INNER | { LEFT | RIGHT | FULL } OUTER } JOIN T2 ON boolean expression T1 { INNER | { LEFT | RIGHT | FULL } OUTER } JOIN T2 USING ( join column list ) The words INNER and OUTER are optional for all JOINs. INNER is the default; LEFT, RIGHT, and FULL are for OUTER JOINs only. The join condition is specified in the ON or USING clause. (The meaning of the join condition depends on the particular join type; see below.) The ON clause takes a boolean value expression of the same kind as is used in a WHERE clause. The USING clause takes a comma-separated list of column names, which the joined tables must have in common, and joins the tables on the equality of those columns as a set, resulting in a joined table having one column for each common column listed and all of the other columns from both tables. 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. 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 First, an INNER JOIN is performed. Then, for a row in T1 that does not satisfy the join condition with any row in T2, a joined row is returned with NULL values in columns of T2. Thus, the joined table unconditionally has a row for each row in T1. RIGHT OUTER JOIN This is like a left join, only that the result table will unconditionally 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 returned 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 returned. NATURAL JOIN T1 NATURAL { INNER | { LEFT | RIGHT | FULL } OUTER JOIN T2 A natural join creates a joined table where every pair of matching column names between the two tables are merged into one column. The join specification is effectively a USING clause containing all the common column names and is otherwise like a Qualified JOIN. Joins of all types can be chained together or nested where either or both of T1 and T2 may be JOINed tables. Parenthesis can be used around JOIN clauses to control the join order which are otherwise left to right. Subqueries Subqueries specifying a derived table must be enclosed in parenthesis and must be named using an AS clause. (See .) FROM (SELECT * FROM table1) AS alias_name This example is equivalent to FROM table1 AS alias_name. Many subquieries can be written as table joins instead. Table and Column Aliases A temporary name can be given to tables and complex table references to be used for references to the derived table in further processing. This is called a table alias. FROM table_reference AS alias Here, alias can be any regular identifier. The alias becomes the new name of the table reference for the current query -- it is no longer possible to refer to the table by the original name (if the table reference was an ordinary base table). Thus SELECT * FROM my_table AS m WHERE my_table.a > 5; is not valid SQL syntax. What will happen instead, as a Postgres extension, is that an implict table reference is added to the FROM clause, so the query is processed as if it was written as SELECT * FROM my_table AS m, my_table WHERE my_table.a > 5; Table aliases are mainly for notational convenience, but it is necessary to use them when joining a table to itself, e.g., SELECT * FROM my_table AS a CROSS JOIN my_table AS b ... Additionally, an alias is required if the table reference is a subquery. Parenthesis are used to resolve ambiguities. The following statement will assign the alias b to the result of the join, unlike the previous example: SELECT * FROM (my_table AS a CROSS JOIN my_table) AS b ... FROM table_reference alias This form is equivalent the previously treated one; the AS key word is noise. FROM table_reference AS alias ( column1 , column2 , ... ) In addition to renaming the table as described above, the columns of the table are also given temporary names. If less column aliases are specified than the actual table has columns, the last columns are not renamed. This syntax is especially useful for self-joins or subqueries. Examples FROM T1 INNER JOIN T2 USING (C) FROM T1 LEFT OUTER JOIN T2 USING (C) FROM (T1 RIGHT OUTER JOIN T2 ON (T1C1=T2C1)) AS DT1 FROM (T1 FULL OUTER JOIN T2 USING (C)) AS DT1 (DT1C1, DT1C2) FROM T1 NATURAL INNER JOIN T2 FROM T1 NATURAL LEFT OUTER JOIN T2 FROM T1 NATURAL RIGHT OUTER JOIN T2 FROM T1 NATURAL FULL OUTER JOIN T2 FROM (SELECT * FROM T1) DT1 CROSS JOIN T2, T3 FROM (SELECT * FROM T1) DT1, T2, T3 Above are some examples of joined tables and complex derived tables. Notice how the AS clause renames or names a derived table and how the optional comma-separated list of column names that follows gives names or renames the columns. The last two FROM clauses produce the same derived table from T1, T2, and T3. The AS keyword was omitted in naming the subquery as DT1. The keywords OUTER and INNER are noise that can be omitted also. WHERE clause The syntax of the WHERE clause is WHERE search condition where search condition is any value expression as defined in that returns a value of type boolean. After the processing of the FROM clause is done, each row of the derived table is checked against the search condition. If the result of the condition is true, the row is kept in the output table, otherwise (that is, if the result is false or NULL) it is discared. The search condition typically references at least some column in the table generated in the FROM clause; this is not required, but otherwise the WHERE clause will be fairly useless. Before the implementation of the JOIN syntax, it was necessary to put the join condition of an inner join in the WHERE 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 products. For outer joins there is no choice in any case: they must be done in the FROM clause. FROM FDT WHERE C1 > 5 FROM FDT WHERE C1 IN (1, 2, 3) FROM FDT WHERE C1 IN (SELECT C1 FROM T2) FROM FDT WHERE C1 IN (SELECT C3 FROM T2 WHERE C2 = FDT.C1 + 10) FROM FDT WHERE C1 BETWEEN (SELECT C3 FROM T2 WHERE C2 = FDT.C1 + 10) AND 100 FROM FDT WHERE EXISTS (SELECT C1 FROM T2 WHERE C2 > FDT.C1) In the examples above, 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 (C2 assumed UNIQUE). Just like any other query, the subqueries can employ complex table expressions. Notice how FDT is referenced in the subqueries. Qualifying C1 as FDT.C1 is only necessary if C1 is the name of a column in the derived input table of the subquery. Qualifying the column name adds clarity even when it is not needed. The column naming scope of an outer query extends into its inner queries. GROUP BY and HAVING clauses After passing the WHERE filter, the derived input table may be subject to grouping, using the GROUP BY clause, and elimination of group rows using the HAVING clause. (The HAVING clause can also be used without GROUP BY, but then it is equivalent to the WHERE clause.) In standard SQL, the GROUP BY clause takes a list of column names, that specify a subrow, from the derived input table produced by the previous WHERE or FROM clause and partitions the table into groups with duplicate subrows such that within a column of the subrow, no column value is distinct from other column values. The resulting derived input table is a special type of table, called a grouped table, which still contains all columns but only references to columns of the grouped subrow, and group aggregates, derived from any of the columns, may appear in derived column value expressions in the query select list. When deriving an output table from a query using a grouped input table, each output row is derived from a corresponding group/partition of the grouped table. Aggregates computed in a derived output column are aggregates on the current partition/group of the grouped input table being processed. Only one output table row results per group/partition of the grouped input table. Postgres has extended the GROUP BY clause to allow some non-standard, but useful behavior. Derived output columns, given names using an AS clause in the query select list, may appear in the GROUP BY clause in combination with, or instead of, the input table column names. Tables may also be grouped by arbitrary expressions. If output table column names appear in the GROUP BY list, then the input table is augmented with additional columns of the output table columns listed in the GROUP BY clause. The value for each row in the additional columns is computed from the value expression that defines the output column in the query select list. The augmented input table is grouped by the column names listed in the GROUP BY clause. The resulting grouped augmented input table is then treated according standard SQL GROUP BY semantics. Only the columns of the unaugmented input table in the grouped subrow (if any), and group aggregates, derived from any of the columns of the unaugmented input table, may be referenced in the value expressions of the derived output columns of the query. Output columns derived with an aggregate expression cannot be named in the GROUP BY clause. A HAVING clause may optionally follow a GROUP BY clause. The HAVING clause selects or eliminates, depending on which perspective is taken, groups from the grouped table derived in the GROUP BY clause that precedes it. The search condition is the same type of expression allowed in a WHERE clause and may reference any of the input table column names in the grouped subrow, but may not reference any others or any named output columns. When the search condition results in TRUE the group is retained, otherwise the group is eliminated. ORDER BY and LIMIT clauses ORDER BY and LIMIT clauses are not clauses of a table expression. They are optional clauses that may follow a query expression and are discussed here because they are commonly used with the clauses above. ORDER BY takes a comma-separated list of columns and performs a cascaded ordering of the table by the columns listed, in the order listed. The keyword DESC or ASC may follow any column name or expression in the list to specify descending or ascending ordering, respectively. Ascending order is the default. The ORDER BY clause conforms to the SQL standard but is extended in Postgres. Postgres allows ORDER BY to reference both output table columns, as named in the select list using the AS clause, and input table columns, as given by the table derived in the FROM clause and other previous clauses. Postgres also extends ORDER BY to allow ordering by arbitrary expressions. If used in a query with a GROUP BY clause, the ORDER BY clause can only reference output table column names and grouped input table columns. LIMIT is not a standard SQL clause. LIMIT is a Postgres extension that limits the number of rows that will be returned from a query. The rows returned by a query using the LIMIT clause are random if no ORDER BY clause is specified. A LIMIT clause may optionally be followed by an OFFSET clause which specifies a number of rows to be skipped in the output table before returning the number of rows specified in the LIMIT clause. ]]>