
Thanks to Michael Deck <deckm@cleansoft.com> for the tipoff. Add more examples for language components.
809 lines
24 KiB
Plaintext
809 lines
24 KiB
Plaintext
<chapter id="syntax">
|
|
<title>SQL Syntax</title>
|
|
|
|
<abstract>
|
|
<para>
|
|
A description of the general syntax of SQL.
|
|
</para>
|
|
</abstract>
|
|
|
|
<para>
|
|
<acronym>SQL</acronym> manipulates sets of data. The language is
|
|
composed of various <firstterm>key words</firstterm>. Arithmetic
|
|
and procedural expressions are allowed. We will cover these topics
|
|
in this chapter; subsequent chapters will include details on data
|
|
types, functions, and operators.
|
|
</para>
|
|
|
|
<sect1>
|
|
<title>Key Words</title>
|
|
|
|
<para>
|
|
<acronym>SQL92</acronym> defines <firstterm>key words</firstterm>
|
|
for the language
|
|
which have specific meaning. Some key words are
|
|
<firstterm>reserved</firstterm>, which indicates that they are
|
|
restricted to appear in only certain contexts. Other key words are
|
|
<firstterm>not restricted</firstterm>, which indicates that in certain
|
|
contexts they
|
|
have a specific meaning but are not otherwise constrained.
|
|
</para>
|
|
|
|
<para>
|
|
<productname>Postgres</productname> implements an extended subset of the
|
|
<acronym>SQL92</acronym> and <acronym>SQL3</acronym> languages. Some language
|
|
elements are not as restricted in this implementation as is
|
|
called for in the language standards, in part due
|
|
to the extensibility features of <productname>Postgres</productname>.
|
|
</para>
|
|
|
|
<para>
|
|
Information on <acronym>SQL92</acronym> and <acronym>SQL3</acronym> key words
|
|
is derived from <xref linkend="DATE97" endterm="DATE97">.
|
|
</para>
|
|
|
|
<sect2>
|
|
<title>Reserved Key Words</title>
|
|
|
|
<para>
|
|
<acronym>SQL92</acronym> and <acronym>SQL3</acronym> have
|
|
<firstterm>reserved key words</firstterm> which are not allowed
|
|
as identifiers and not allowed in any usage other than as fundamental
|
|
tokens in <acronym>SQL</acronym> statements.
|
|
<productname>Postgres</productname> has additional key words
|
|
which have similar restrictions. In particular, these key words
|
|
are not allowed as column or table names, though in some cases
|
|
they are allowed to be column labels (i.e. in AS clauses).
|
|
</para>
|
|
|
|
<tip>
|
|
<para>
|
|
Any string can be specified as an identifier if surrounded by
|
|
double quotes (<quote>like this!</quote>). Some care is required since
|
|
such an identifier will be case sensitive
|
|
and will retain embedded whitespace other special characters.
|
|
</para>
|
|
</tip>
|
|
|
|
<para>
|
|
The following are <productname>Postgres</productname>
|
|
reserved words which are neither <acronym>SQL92</acronym>
|
|
nor <acronym>SQL3</acronym> reserved words. These are allowed
|
|
to be present as column labels, but not as identifiers:
|
|
|
|
<programlisting>
|
|
ABORT ANALYZE
|
|
BINARY
|
|
CLUSTER CONSTRAINT COPY
|
|
DO
|
|
EXPLAIN EXTEND
|
|
LISTEN LOAD LOCK
|
|
MOVE
|
|
NEW NONE NOTIFY
|
|
RESET
|
|
SETOF SHOW
|
|
UNLISTEN UNTIL
|
|
VACUUM VERBOSE
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
The following are <productname>Postgres</productname>
|
|
reserved words which are also <acronym>SQL92</acronym>
|
|
or <acronym>SQL3</acronym> reserved words, and which
|
|
are allowed to be present as column labels, but not as identifiers:
|
|
|
|
<programlisting>
|
|
CASE COALESCE CROSS CURRENT
|
|
ELSE END
|
|
FALSE FOREIGN
|
|
GLOBAL GROUP
|
|
LOCAL
|
|
NULLIF
|
|
ORDER
|
|
POSITION PRECISION
|
|
TABLE THEN TRANSACTION TRUE
|
|
WHEN
|
|
</programlisting>
|
|
|
|
The following are <productname>Postgres</productname>
|
|
reserved words which are also <acronym>SQL92</acronym>
|
|
or <acronym>SQL3</acronym> reserved words:
|
|
|
|
<programlisting>
|
|
ADD ALL ALTER AND ANY AS ASC
|
|
BEGIN BETWEEN BOTH BY
|
|
CASCADE CAST CHAR CHARACTER CHECK CLOSE
|
|
COLLATE COLUMN COMMIT CONSTRAINT
|
|
CREATE CURRENT_DATE CURRENT_TIME
|
|
CURRENT_TIMESTAMP CURRENT_USER CURSOR
|
|
DECIMAL DECLARE DEFAULT DELETE DESC DISTINCT DROP
|
|
EXECUTE EXISTS EXTRACT
|
|
FETCH FLOAT FOR FROM FULL
|
|
GRANT
|
|
HAVING
|
|
IN INNER INSERT INTERVAL INTO IS
|
|
JOIN
|
|
LEADING LEFT LIKE LOCAL
|
|
NAMES NATIONAL NATURAL NCHAR NO NOT NULL NUMERIC
|
|
ON OR OUTER
|
|
PARTIAL PRIMARY PRIVILEGES PROCEDURE PUBLIC
|
|
REFERENCES REVOKE RIGHT ROLLBACK
|
|
SELECT SET SUBSTRING
|
|
TO TRAILING TRIM
|
|
UNION UNIQUE UPDATE USER USING
|
|
VALUES VARCHAR VARYING VIEW
|
|
WHERE WITH WORK
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
The following are <acronym>SQL92</acronym> reserved key words which
|
|
are not <productname>Postgres</productname> reserved key words, but which
|
|
if used as function names are always translated into the function
|
|
<function>length</function>:
|
|
|
|
<programlisting>
|
|
CHAR_LENGTH CHARACTER_LENGTH
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
The following are <acronym>SQL92</acronym> or <acronym>SQL3</acronym>
|
|
reserved key words which
|
|
are not <productname>Postgres</productname> reserved key words, but
|
|
if used as type names are always translated into an alternate, native type:
|
|
|
|
<programlisting>
|
|
BOOLEAN DOUBLE FLOAT INT INTEGER INTERVAL REAL SMALLINT
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
The following are either <acronym>SQL92</acronym>
|
|
or <acronym>SQL3</acronym> reserved key words
|
|
which are not key words in <productname>Postgres</productname>.
|
|
These have no proscribed usage in <productname>Postgres</productname>
|
|
at the time of writing (v6.5) but may become reserved key words in the
|
|
future:
|
|
|
|
<note>
|
|
<para>
|
|
Some of these key words represent functions in <acronym>SQL92</acronym>.
|
|
These functions are defined in <productname>Postgres</productname>,
|
|
but the parser does not consider the names to be key words and they are allowed
|
|
in other contexts.
|
|
</para>
|
|
</note>
|
|
|
|
<programlisting>
|
|
ALLOCATE ARE ASSERTION AT AUTHORIZATION AVG
|
|
BIT BIT_LENGTH
|
|
CASCADED CATALOG COLLATION CONNECT CONNECTION
|
|
CONSTRAINTS CONTINUE CONVERT CORRESPONDING COUNT
|
|
DATE DEALLOCATE DEC DESCRIBE DESCRIPTOR DIAGNOSTICS DISCONNECT DOMAIN
|
|
END-EXEC ESCAPE EXCEPT EXCEPTION EXEC EXTERNAL
|
|
FIRST FOUND
|
|
GET GO GOTO
|
|
IDENTITY IMMEDIATE INDICATOR INITIALLY INPUT INTERSECT ISOLATION
|
|
LAST LEVEL LOWER
|
|
MAX MIN MODULE
|
|
OCTET_LENGTH OPEN OUTPUT OVERLAPS
|
|
PREPARE PRESERVE
|
|
RESTRICT ROWS
|
|
SCHEMA SECTION SESSION SESSION_USER SIZE SOME
|
|
SQL SQLCODE SQLERROR SQLSTATE SUM SYSTEM_USER
|
|
TEMPORARY TRANSLATE TRANSLATION
|
|
UNKNOWN UPPER USAGE
|
|
VALUE
|
|
WHENEVER WRITE
|
|
</programlisting>
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title>Non-reserved Keywords</title>
|
|
|
|
<para>
|
|
<acronym>SQL92</acronym> and <acronym>SQL3</acronym> have
|
|
<firstterm>non-reserved keywords</firstterm> which have
|
|
a prescribed meaning in the language but which are also allowed
|
|
as identifiers.
|
|
<productname>Postgres</productname> has additional keywords
|
|
which allow similar unrestricted usage.
|
|
In particular, these keywords
|
|
are allowed as column or table names.
|
|
</para>
|
|
|
|
<para>
|
|
The following are <productname>Postgres</productname>
|
|
non-reserved key words which are neither <acronym>SQL92</acronym>
|
|
nor <acronym>SQL3</acronym> non-reserved key words:
|
|
|
|
<programlisting>
|
|
ACCESS AFTER AGGREGATE
|
|
BACKWARD BEFORE
|
|
CACHE CREATEDB CREATEUSER CYCLE
|
|
DATABASE DELIMITERS
|
|
EACH ENCODING EXCLUSIVE
|
|
FORWARD FUNCTION
|
|
HANDLER
|
|
INCREMENT INDEX INHERITS INSENSITIVE INSTEAD ISNULL
|
|
LANCOMPILER LOCATION
|
|
MAXVALUE MINVALUE MODE
|
|
NOCREATEDB NOCREATEUSER NOTHING NOTNULL
|
|
OIDS OPERATOR
|
|
PASSWORD PROCEDURAL
|
|
RECIPE RENAME RETURNS ROW RULE
|
|
SEQUENCE SERIAL SHARE START STATEMENT STDIN STDOUT
|
|
TRUSTED
|
|
VALID VERSION
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
The following are <productname>Postgres</productname>
|
|
non-reserved key words which are <acronym>SQL92</acronym>
|
|
or <acronym>SQL3</acronym> reserved key words:
|
|
|
|
<programlisting>
|
|
ABSOLUTE ACTION
|
|
DAY
|
|
HOUR
|
|
INSENSITIVE
|
|
KEY
|
|
LANGUAGE
|
|
MATCH MINUTE MONTH
|
|
NEXT
|
|
OF ONLY OPTION
|
|
PRIOR PRIVILEGES
|
|
READ RELATIVE
|
|
SCROLL SECOND
|
|
TIME TIMESTAMP TIMEZONE_HOUR TIMEZONE_MINUTE TRIGGER
|
|
YEAR
|
|
ZONE
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
The following are <productname>Postgres</productname>
|
|
non-reserved key words which are also either <acronym>SQL92</acronym>
|
|
or <acronym>SQL3</acronym> non-reserved key words:
|
|
|
|
<programlisting>
|
|
COMMITTED SERIALIZABLE TYPE
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
The following are either <acronym>SQL92</acronym>
|
|
or <acronym>SQL3</acronym> non-reserved key words which are not
|
|
key words of any kind in <productname>Postgres</productname>:
|
|
|
|
<programlisting>
|
|
ADA
|
|
C CATALOG_NAME CHARACTER_SET_CATALOG CHARACTER_SET_NAME
|
|
CHARACTER_SET_SCHEMA CLASS_ORIGIN COBOL COLLATION_CATALOG
|
|
COLLATION_NAME COLLATION_SCHEMA COLUMN_NAME
|
|
COMMAND_FUNCTION CONDITION_NUMBER
|
|
CONNECTION_NAME CONSTRAINT_CATALOG CONSTRAINT_NAME
|
|
CONSTRAINT_SCHEMA CURSOR_NAME
|
|
DATA DATE_TIME_INTERVAL_CODE DATE_TIME_INTERVAL_PRECISION
|
|
DYNAMIC_FUNCTION
|
|
FORTRAN
|
|
LENGTH
|
|
MESSAGE_LENGTH MESSAGE_OCTET_LENGTH MORE MUMPS
|
|
NAME NULLABLE NUMBER
|
|
PAD PASCAL PLI
|
|
REPEATABLE RETURNED_LENGTH RETURNED_OCTET_LENGTH
|
|
RETURNED_SQLSTATE ROW_COUNT
|
|
SCALE SCHEMA_NAME SERVER_NAME SPACE
|
|
SUBCLASS_ORIGIN
|
|
TABLE_NAME
|
|
UNCOMMITTED UNNAMED
|
|
</programlisting>
|
|
</para>
|
|
</sect2>
|
|
</sect1>
|
|
|
|
<sect1>
|
|
<title>Comments</title>
|
|
|
|
<para>
|
|
A <firstterm>comment</firstterm>
|
|
is an arbitrary sequence of characters following double dashes up to the end
|
|
of the line. We also support double-slashes as comments, e.g.:
|
|
|
|
<programlisting>
|
|
-- This is a standard SQL comment
|
|
// And this is another supported comment style, like C++
|
|
</programlisting>
|
|
|
|
We also support C-style block comments, e.g.:
|
|
|
|
<programlisting>
|
|
/* multi
|
|
line
|
|
comment
|
|
*/
|
|
</programlisting>
|
|
</para>
|
|
</sect1>
|
|
|
|
<sect1>
|
|
<title>Names</title>
|
|
|
|
<para>
|
|
Names in SQL are sequences of less than NAMEDATALEN alphanumeric characters,
|
|
starting with an alphabetic character. By default, NAMEDATALEN is set
|
|
to 32, but at the time the system is built, NAMEDATALEN can be changed
|
|
by changing the <literal>#define</literal> in
|
|
src/backend/include/postgres.h.
|
|
Underscore ("_") is considered an alphabetic character.
|
|
</para>
|
|
|
|
<para>
|
|
In some contexts, names may contain other characters if surrounded
|
|
by double quotes. For example, table or column names may contain otherwise
|
|
disallowed characters such as spaces, ampersands, etc. using this
|
|
technique.
|
|
</para>
|
|
</sect1>
|
|
|
|
<sect1>
|
|
<title>Constants</title>
|
|
|
|
<para>
|
|
There are six types of
|
|
<firstterm>constants</firstterm>
|
|
for use in SQL. They are described below.
|
|
</para>
|
|
|
|
<sect2>
|
|
<title>String Constants</title>
|
|
|
|
<para>
|
|
<firstterm>Strings</firstterm>
|
|
in SQL are arbitrary sequences of ASCII characters bounded by single
|
|
quotes ("'", e.g. <literal>'This is a string'</literal>).
|
|
Uppercase alphabetics within strings are accepted
|
|
literally. Non-printing characters may be embedded within strings by
|
|
prepending them with a backslash
|
|
("\"; e.g. "\<replaceable>tab</replaceable>".
|
|
SQL92 allows single quotes to be embedded in strings by typing two
|
|
adjacent single quotes (e.g. 'Dianne''s horse'), and for
|
|
historical reasons <productname>Postgres</productname> also allows
|
|
single quotes to be escaped with a backslash
|
|
(e.g. 'Dianne\'s horse').
|
|
</para>
|
|
|
|
<para>
|
|
Because of the limitations on
|
|
instance sizes, string constants are currently limited to a length of
|
|
a little less than 8192 bytes. Larger strings may be handled using the
|
|
Postgres Large Object interface.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title>Integer Constants</title>
|
|
|
|
<para>
|
|
<firstterm>Integer constants</firstterm>
|
|
in SQL are collection of ASCII digits with no decimal point. Legal
|
|
values range from -2147483648 to +2147483647. This will vary
|
|
depending on the operating system and host machine.
|
|
</para>
|
|
|
|
<para>
|
|
Note that larger integers can be specified for <type>int8</type>
|
|
by using <acronym>SQL92</acronym> string notation or
|
|
<productname>Postgres</productname> type notation:
|
|
|
|
<programlisting>
|
|
int8 '4000000000' -- string style
|
|
'4000000000'::int8 -- Postgres (historical) style
|
|
</programlisting>
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title>Floating Point Constants</title>
|
|
|
|
<para>
|
|
<firstterm>Floating point constants</firstterm>
|
|
consist of an integer part, a decimal point, and a fraction part or
|
|
scientific notation of the following format:
|
|
|
|
<synopsis>
|
|
{<replaceable>dig</replaceable>}.{<replaceable>dig</replaceable>} [e [+-] {<replaceable>dig</replaceable>}]
|
|
</synopsis>
|
|
|
|
where <replaceable>dig</replaceable> is one or more digits.
|
|
You must include at least one <replaceable>dig</replaceable> after the
|
|
period and after the [+-] if you use those options. An exponent with
|
|
a missing mantissa has a mantissa of 1 inserted. There may be no
|
|
extra characters embedded in the string.
|
|
</para>
|
|
|
|
<para>
|
|
Floating point constaints are of type
|
|
<type>float8</type>. <type>float4</type> can be specified
|
|
explicitly by using <acronym>SQL92</acronym> string notation or
|
|
<productname>Postgres</productname> type notation:
|
|
|
|
<programlisting>
|
|
float4 '1.23' -- string style
|
|
'1.23'::float4 -- Postgres (historical) style
|
|
</programlisting>
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title>Constants of Postgres User-Defined Types</title>
|
|
|
|
<para>
|
|
A constant of an
|
|
<emphasis>arbitrary</emphasis>
|
|
type can be entered using the notations:
|
|
|
|
<synopsis>
|
|
<replaceable>type</replaceable> '<replaceable>string</replaceable>'
|
|
'<replaceable>string</replaceable>'::<replaceable>type</replaceable>
|
|
CAST '<replaceable>string</replaceable>' AS <replaceable>type</replaceable>
|
|
</synopsis>
|
|
|
|
The value inside the string is passed to the input
|
|
conversion routine for the type called
|
|
<replaceable>type</replaceable>. The result is a
|
|
constant of the indicated type. The explicit typecast may be omitted
|
|
if there is no ambiguity as to the type the constant must be, in which
|
|
case it is automatically coerced.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title>Array constants</title>
|
|
|
|
<para>
|
|
<firstterm>Array constants</firstterm>
|
|
are arrays of any Postgres type, including other arrays, string
|
|
constants, etc. The general format of an array constant is the
|
|
following:
|
|
|
|
<synopsis>
|
|
{<replaceable>val1</replaceable><replaceable>delim</replaceable><replaceable>val2</replaceable><replaceable>delim</replaceable>}
|
|
</synopsis>
|
|
|
|
where <replaceable>delim</replaceable>
|
|
is the delimiter for the type stored in the <literal>pg_type</literal> class.
|
|
(For built-in types, this is the comma character (","). An
|
|
example of an array constant is
|
|
|
|
<programlisting>
|
|
{{1,2,3},{4,5,6},{7,8,9}}
|
|
</programlisting>
|
|
|
|
This constant is a two-dimensional, 3 by 3 array consisting of three
|
|
sub-arrays of integers.
|
|
</para>
|
|
|
|
<para>
|
|
Individual array elements can and should be placed between quotation
|
|
marks whenever possible to avoid ambiguity problems with respect to
|
|
leading white space.
|
|
</para>
|
|
</sect2>
|
|
</sect1>
|
|
|
|
<sect1>
|
|
<title>Fields and Columns</title>
|
|
|
|
<sect2>
|
|
<title>Fields</title>
|
|
|
|
<para>
|
|
A <firstterm>field</firstterm>
|
|
is either an attribute of a given class or one of the following:
|
|
|
|
<variablelist>
|
|
<varlistentry>
|
|
<term>oid</term>
|
|
<listitem>
|
|
<para>
|
|
stands for the unique identifier of an instance which is added by
|
|
Postgres to all instances automatically. Oids are not reused and are 32
|
|
bit quantities.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term>xmin</term>
|
|
<listitem>
|
|
<para>
|
|
The identity of the inserting transaction.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term>xmax</term>
|
|
<listitem>
|
|
<para>
|
|
The identity of the deleting transaction.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term>cmin</term>
|
|
<listitem>
|
|
<para>
|
|
The command identifier within the transaction.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term>cmax</term>
|
|
<listitem>
|
|
<para>
|
|
The identity of the deleting command.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
</variablelist>
|
|
</para>
|
|
|
|
<para>
|
|
For further information on these fields consult
|
|
<xref linkend="STON87a" endterm="STON87a">.
|
|
Times are represented internally as instances of the
|
|
<literal>abstime</literal>
|
|
data type. Transaction and command identifiers are 32 bit quantities.
|
|
Transactions are assigned sequentially starting at 512.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title>Columns</title>
|
|
|
|
<para>
|
|
A <firstterm>column</firstterm> is a construct of the form:
|
|
|
|
<synopsis>
|
|
<replaceable>instance</replaceable>{.<replaceable>composite_field</replaceable>}.<replaceable>field</replaceable> `['<replaceable>number</replaceable>`]'
|
|
</synopsis>
|
|
|
|
<replaceable>instance</replaceable>
|
|
identifies a particular class and can be thought of as standing for
|
|
the instances of that class. An instance variable is either a class
|
|
name, a surrogate for a class defined by means of a FROM clause,
|
|
or the keyword NEW or CURRENT.
|
|
NEW and CURRENT can only appear in the action portion of a rule, while
|
|
other instance variables can be used in any SQL statement.
|
|
<replaceable>composite_field</replaceable>
|
|
is a field of of one of the Postgres composite types,
|
|
while successive composite fields address attributes in the
|
|
class(s) to which the composite field evaluates. Lastly,
|
|
<replaceable>field</replaceable>
|
|
is a normal (base type) field in the class(s) last addressed. If
|
|
<replaceable>field</replaceable>
|
|
is of type <literal>array</literal>,
|
|
then the optional <replaceable>number</replaceable>
|
|
designator indicates a specific element in the array. If no number is
|
|
indicated, then all array elements are returned.
|
|
</para>
|
|
</sect2>
|
|
</sect1>
|
|
|
|
<sect1>
|
|
<title>Operators</title>
|
|
|
|
<para>
|
|
Any built-in system, or user-defined operator may be used in SQL.
|
|
For the list of built-in and system operators consult
|
|
<xref linkend="operators" endterm="operators-title">.
|
|
For a list of user-defined operators consult your system administrator
|
|
or run a query on the <literal>pg_operator</literal> class.
|
|
Parentheses may be used for arbitrary grouping of operators in expressions.
|
|
</para>
|
|
</sect1>
|
|
|
|
<sect1>
|
|
<title>Expressions</title>
|
|
|
|
<para>
|
|
<acronym>SQL92</acronym> allows <firstterm>expressions</firstterm>
|
|
to transform data in tables. Expressions may contain operators
|
|
(see <xref linkend="operators" endterm="operators-title">
|
|
for more details) and functions
|
|
(<xref linkend="functions" endterm="functions-title"> has
|
|
more information).
|
|
</para>
|
|
|
|
<para>
|
|
An expression is one of the following:
|
|
|
|
<simplelist>
|
|
<member>( a_expr )</member>
|
|
<member>constant</member>
|
|
<member>attribute</member>
|
|
<member><replaceable>a_expr</replaceable> <replaceable>binary_operator</replaceable> <replaceable>a_expr</replaceable></member>
|
|
<member><replaceable>a_expr</replaceable> <replaceable>right_unary_operator</replaceable></member>
|
|
<member><replaceable>left_unary_operator</replaceable> <replaceable>a_expr</replaceable></member>
|
|
<member>parameter</member>
|
|
<member>functional expressions</member>
|
|
<member>aggregate expressions</member>
|
|
</simplelist>
|
|
</para>
|
|
|
|
<para>
|
|
We have already discussed constants and attributes. The two kinds of
|
|
operator expressions indicate respectively binary and left_unary
|
|
expressions. The following sections discuss the remaining options.
|
|
</para>
|
|
|
|
<sect2>
|
|
<title>Parameters</title>
|
|
|
|
<para>
|
|
A <firstterm>parameter</firstterm>
|
|
is used to indicate a parameter in a SQL function. Typically this
|
|
is used in SQL function definition statement. The form of a
|
|
parameter is:
|
|
|
|
<synopsis>
|
|
$<replaceable class="parameter">number</replaceable>
|
|
</synopsis>
|
|
</para>
|
|
|
|
<para>
|
|
For example, consider the definition of a function,
|
|
<function>dept</function>, as
|
|
|
|
<programlisting>
|
|
CREATE FUNCTION dept (name)
|
|
RETURNS dept
|
|
AS 'select * from
|
|
dept where name=$1'
|
|
LANGUAGE 'sql';
|
|
</programlisting>
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title>Functional Expressions</title>
|
|
|
|
<para>
|
|
A <firstterm>functional expression</firstterm>
|
|
is the name of a legal SQL function, followed by its argument list
|
|
enclosed in parentheses:
|
|
|
|
<synopsis>
|
|
<replaceable>function</replaceable> (<replaceable>a_expr</replaceable> [, <replaceable>a_expr</replaceable> )
|
|
</synopsis>
|
|
</para>
|
|
|
|
<para>
|
|
For example, the following computes the square root of an employee
|
|
salary:
|
|
|
|
<programlisting>
|
|
sqrt(emp.salary)
|
|
</programlisting>
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title>Aggregate Expression</title>
|
|
|
|
<para>
|
|
An <firstterm>aggregate expression</firstterm>
|
|
represents a simple aggregate (i.e., one that computes a single value)
|
|
or an aggregate function (i.e., one that computes a set of values).
|
|
The syntax is the following:
|
|
|
|
<synopsis>
|
|
<replaceable>aggregate_name</replaceable> (<replaceable>attribute</replaceable>)
|
|
</synopsis>
|
|
|
|
where <replaceable>aggregate_name</replaceable>
|
|
must be a previously defined aggregate.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title>Target List</title>
|
|
|
|
<para>
|
|
A <firstterm>target list</firstterm>
|
|
is a parenthesized, comma-separated list of one or more elements, each
|
|
of which must be of the form:
|
|
|
|
<synopsis>
|
|
<replaceable>a_expr</replaceable> [ AS <replaceable>result_attname</replaceable> ]
|
|
</synopsis>
|
|
|
|
where <replaceable>result_attname</replaceable>
|
|
is the name of the attribute to be created (or an
|
|
already existing attribute name in the case of update statements.) If
|
|
<replaceable>result_attname</replaceable>
|
|
is not present, then
|
|
<replaceable>a_expr</replaceable>
|
|
must contain only one attribute name which is assumed to be the name
|
|
of the result field. In <productname>Postgres</productname>
|
|
default naming is only used if
|
|
<replaceable>a_expr</replaceable>
|
|
is an attribute.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title>Qualification</title>
|
|
|
|
<para>
|
|
A <firstterm>qualification</firstterm>
|
|
consists of any number of clauses connected by the logical operators:
|
|
|
|
<simplelist>
|
|
<member>NOT</member>
|
|
<member>AND</member>
|
|
<member>OR</member>
|
|
</simplelist>
|
|
|
|
A clause is an <replaceable>a_expr</replaceable>
|
|
that evaluates to a <literal>boolean</literal> over a set of instances.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title>From List</title>
|
|
|
|
<para>
|
|
The <firstterm>from list</firstterm>
|
|
is a comma-separated list of <firstterm>from expressions</firstterm>.
|
|
Each "from expression" is of the form:
|
|
|
|
<synopsis>
|
|
[ <replaceable>class_reference</replaceable> ] <replaceable>instance_variable</replaceable>
|
|
{, [ <replaceable>class_ref</replaceable> ] <replaceable>instance_variable</replaceable>... }
|
|
</synopsis>
|
|
|
|
where <replaceable>class_reference</replaceable>
|
|
is of the form
|
|
|
|
<synopsis>
|
|
<replaceable>class_name</replaceable> [ * ]
|
|
</synopsis>
|
|
|
|
The "from expression"
|
|
defines one or more instance variables to range over the class
|
|
indicated in <replaceable>class_reference</replaceable>.
|
|
One can also request
|
|
the instance variable to range over all classes that are beneath the
|
|
indicated class in the inheritance hierarchy by postpending the
|
|
designator asterisk ("*").
|
|
</para>
|
|
</sect2>
|
|
</sect1>
|
|
</chapter>
|
|
|
|
<!-- Keep this comment at the end of the file
|
|
Local variables:
|
|
mode: sgml
|
|
sgml-omittag:nil
|
|
sgml-shorttag:t
|
|
sgml-minimize-attributes:nil
|
|
sgml-always-quote-attributes:t
|
|
sgml-indent-step:1
|
|
sgml-indent-data:t
|
|
sgml-parent-document:nil
|
|
sgml-default-dtd-file:"./reference.ced"
|
|
sgml-exposed-tags:nil
|
|
sgml-local-catalogs:"/usr/lib/sgml/CATALOG"
|
|
sgml-local-ecat-files:nil
|
|
End:
|
|
-->
|