PostgreSQL 7.4.8 Documentation | ||||
---|---|---|---|---|
Prev | Fast Backward | Fast Forward | Next |
This chapter describes the syntax of SQL. It forms the foundation for understanding the following chapters which will go into detail about how the SQL commands are applied to define and modify data.
We also advise users who are already familiar with SQL to read this chapter carefully because there are several rules and concepts that are implemented inconsistently among SQL databases or that are specific to PostgreSQL.
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 usefully be 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 Part VI.
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 Appendix C.
SQL identifiers and key words must begin with a letter (a-z, but also letters with diacritical marks and non-Latin letters) or an underscore (_). Subsequent characters in an identifier or key word can be letters, underscores, digits (0-9), or dollar signs ($). Note that dollar signs are not allowed in identifiers according to the letter of the SQL standard, so their use may render applications less portable. The SQL standard will not define a key word that contains digits or starts or ends with an underscore, so identifiers of this form are safe against possible conflict with future extensions of the standard.
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 64 so the maximum identifier length is 63. If this limit is problematic, it can be raised by changing the NAMEDATALEN constant 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 convention often used is 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 a key word 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 this:
UPDATE "my_table" SET "a" = 5;
Quoted identifiers can contain any character other than a double quote itself. (To include a double quote, write two double quotes.) 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 PostgreSQL, but "Foo" and "FOO" are different from these three and each other. (The folding of unquoted names to lower case in PostgreSQL is incompatible with the SQL standard, which says that unquoted names should be folded to upper case. Thus, foo should be equivalent to "FOO" not "foo" according to the standard. If you want to write portable applications you are advised to always quote a particular name or never quote it.)
There are three kinds of implicitly-typed constants in PostgreSQL: strings, bit strings, and 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.
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 PostgreSQL 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 a byte with the corresponding code. (It is your responsibility that the byte sequences you create are valid characters in the server character set encoding.) 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. (This slightly bizarre behavior is specified by SQL; PostgreSQL is following the standard.)
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.
Alternatively, bit-string constants can be specified in hexadecimal notation, using a leading X (upper or lower case), e.g., X'1FF'. This notation is equivalent to a bit-string constant with four binary digits for each hexadecimal digit.
Both forms of bit-string constant can be continued across lines in the same way as regular string constants.
Numeric constants are accepted in these general forms:
digits digits.[digits][e[+-]digits] [digits].digits[e[+-]digits] digitse[+-]digits
where digits is one or more decimal digits (0 through 9). At least one digit must be before or after the decimal point, if one is used. At least one digit must follow the exponent marker (e), if one is present. There may not be any spaces or other characters embedded in the constant. Note that any leading plus or minus sign is not actually considered part of the constant; it is an operator applied to the constant.
These are some examples of valid numeric constants:
42
3.5
4.
.001
5e2
1.925e-3
A numeric constant that contains neither a decimal point nor an exponent is initially presumed to be type integer if its value fits in type integer (32 bits); otherwise it is presumed to be type bigint if its value fits in type bigint (64 bits); otherwise it is taken to be type numeric. Constants that contain decimal points and/or exponents are always initially presumed to be type numeric.
The initially assigned data type of a numeric constant is just a starting point for the type resolution algorithms. In most cases the constant will be automatically coerced to the most appropriate type depending on context. When necessary, you can force a numeric value to be interpreted as a specific data type by casting it. For example, you can force a numeric value to be treated as type real (float4) by writing
REAL '1.23' -- string style 1.23::REAL -- PostgreSQL (historical) style
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 string's text 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 ( 'string' )
but not all type names may be used in this way; see Section 4.2.8 for details.
The ::, CAST(), and function-call syntaxes can also be used to specify run-time type conversions of arbitrary expressions, as discussed in Section 4.2.8. But the form type 'string' can only be used to specify the type of a literal constant. Another restriction on type 'string' is that it does not work for array types; use :: or CAST() to specify the type of an array constant.
An operator name is a sequence of up to NAMEDATALEN-1 (63 by default) characters from the following list:
+ - * / < > = ~ ! @ # % ^ & | ` ?
There are a few restrictions on operator names, however:-- and /* cannot appear anywhere in an operator name, since they will be taken as the start of a comment.
A multiple-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 PostgreSQL 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 PostgreSQL reads it as two operator names not one.
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 a positional parameter in the body of a function definition or a prepared statement. In other contexts the dollar sign may be part of an identifier.
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 Section 8.10 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 within a string constant or quoted identifier.
The colon (:) is used to select "slices" from arrays. (See Section 8.10.) 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 numeric constants, and to separate schema, table, and column names.
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 SQL comment
Alternatively, C-style block comments can be used:
/* multiline 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 the SQL standard 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.
Table 4-1 shows the precedence and associativity of the operators in PostgreSQL. Most operators have the same precedence and are left-associative. The precedence and associativity of the operators is hard-wired into the parser. 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 -- until it is too late -- that ! is defined as a postfix operator, not an infix one. To get the desired behavior in this case, you must write
SELECT (5 !) - 6;
This is the price one pays for extensibility.
Table 4-1. Operator Precedence (decreasing)
Operator/Element | Associativity | Description |
---|---|---|
. | left | table/column name separator |
:: | left | PostgreSQL-style typecast |
[ ] | left | array element selection |
- | right | unary minus |
^ | left | exponentiation |
* / % | left | multiplication, division, modulo |
+ - | left | addition, subtraction |
IS | IS TRUE, IS FALSE, IS UNKNOWN, IS 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 SIMILAR | 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.
When a schema-qualified operator name is used in the OPERATOR syntax, as for example in
SELECT 3 OPERATOR(pg_catalog.+) 4;
the OPERATOR construct is taken to have the default precedence shown in Table 4-1 for "any other" operator. This is true no matter which specific operator name appears inside OPERATOR().