diff --git a/doc/src/sgml/advanced.sgml b/doc/src/sgml/advanced.sgml
index 7fbf108942..acd548dd29 100644
--- a/doc/src/sgml/advanced.sgml
+++ b/doc/src/sgml/advanced.sgml
@@ -1,5 +1,5 @@
@@ -46,14 +46,14 @@ $Header: /cvsroot/pgsql/doc/src/sgml/advanced.sgml,v 1.27 2002/02/12 22:25:15 mo
view over the query, which gives a name to
the query that you can refer to like an ordinary table.
-
+
CREATE VIEW myview AS
SELECT city, temp_lo, temp_hi, prcp, date, location
FROM weather, cities
WHERE city = name;
SELECT * FROM myview;
-
+
@@ -101,32 +101,30 @@ SELECT * FROM myview;
The new declaration of the tables would look like this:
-
+
CREATE TABLE cities (
- city varchar(80) primary key,
- location point
+ city varchar(80) primary key,
+ location point
);
CREATE TABLE weather (
- city varchar(80) references cities,
- temp_lo int,
- temp_hi int,
- prcp real,
- date date
+ city varchar(80) references cities,
+ temp_lo int,
+ temp_hi int,
+ prcp real,
+ date date
);
-
-
+
Now try inserting an invalid record:
-
+
INSERT INTO weather VALUES ('Berkeley', 45, 53, 0.0, '1994-11-28');
-
+
-
+
ERROR: <unnamed> referential integrity violation - key referenced from weather not found in cities
-
-
+
@@ -162,7 +160,8 @@ ERROR: <unnamed> referential integrity violation - key referenced from we
Suppose that we want to record a payment of $100.00 from Alice's account
to Bob's account. Simplifying outrageously, the SQL commands for this
might look like
-
+
+
UPDATE accounts SET balance = balance - 100.00
WHERE name = 'Alice';
UPDATE branches SET balance = balance - 100.00
@@ -171,7 +170,10 @@ UPDATE accounts SET balance = balance + 100.00
WHERE name = 'Bob';
UPDATE branches SET balance = balance + 100.00
WHERE name = (SELECT branch_name FROM accounts WHERE name = 'Bob');
-
+
+
+
+
The details of these commands are not important here; the important
point is that there are several separate updates involved to accomplish
this rather simple operation. Our bank's officers will want to be
@@ -219,13 +221,17 @@ UPDATE branches SET balance = balance + 100.00
the SQL commands of the transaction with
BEGIN> and COMMIT> commands. So our banking
transaction would actually look like
-
+
+
BEGIN;
UPDATE accounts SET balance = balance - 100.00
WHERE name = 'Alice';
-- etc etc
COMMIT;
-
+
+
+
+
If, partway through the transaction, we decide we don't want to
commit (perhaps we just noticed that Alice's balance went negative),
we can issue the command ROLLBACK> instead of
@@ -272,25 +278,25 @@ COMMIT;
implicitly when you list all cities. If you're really clever you
might invent some scheme like this:
-
+
CREATE TABLE capitals (
- name text,
- population real,
- altitude int, -- (in ft)
- state char(2)
+ name text,
+ population real,
+ altitude int, -- (in ft)
+ state char(2)
);
CREATE TABLE non_capitals (
- name text,
- population real,
- altitude int -- (in ft)
+ name text,
+ population real,
+ altitude int -- (in ft)
);
CREATE VIEW cities AS
- SELECT name, population, altitude FROM capitals
- UNION
- SELECT name, population, altitude FROM non_capitals;
-
+ SELECT name, population, altitude FROM capitals
+ UNION
+ SELECT name, population, altitude FROM non_capitals;
+
This works OK as far as querying goes, but it gets ugly when you
need to update several rows, to name one thing.
@@ -299,18 +305,20 @@ CREATE VIEW cities AS
A better solution is this:
-
+
CREATE TABLE cities (
- name text,
- population real,
- altitude int -- (in ft)
+ name text,
+ population real,
+ altitude int -- (in ft)
);
CREATE TABLE capitals (
- state char(2)
+ state char(2)
) INHERITS (cities);
-
+
+
+
In this case, a row of capitalsinherits all columns (name>,
population>, and altitude>) from its
@@ -328,22 +336,22 @@ CREATE TABLE capitals (
including state capitals, that are located at an altitude
over 500 ft.:
-
+
SELECT name, altitude
- FROM cities
- WHERE altitude > 500;
-
+ FROM cities
+ WHERE altitude > 500;
+
which returns:
-
+
name | altitude
-----------+----------
Las Vegas | 2174
Mariposa | 1953
Madison | 845
(3 rows)
-
+
@@ -351,11 +359,11 @@ SELECT name, altitude
all the cities that are not state capitals and
are situated at an altitude of 500 ft. or higher:
-
+
SELECT name, altitude
FROM ONLY cities
WHERE altitude > 500;
-
+
name | altitude
@@ -363,7 +371,7 @@ SELECT name, altitude
Las Vegas | 2174
Mariposa | 1953
(2 rows)
-
+
@@ -397,7 +405,6 @@ SELECT name, altitude
site for links to more resources.
-
@@ -2637,7 +2637,8 @@ SELECT * FROM test1 WHERE a;
The inet type holds an IP host address, and
optionally the identity of the subnet it is in, all in one field.
The subnet identity is represented by the number of bits in the
- network part of the address (the netmask). If the netmask is 32,
+ network part of the address (the netmask). If the
+ netmask is 32,
then the value does not indicate a subnet, only a single host.
Note that if you want to accept networks only, you should use the
cidr type rather than inet.
diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 1c88322891..c208f64504 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -1,472 +1,334 @@
-
- Functions and Operators
+
+ Functions and Operators
-
- functions
-
-
-
- operators
-
-
-
- PostgreSQL provides a large number of
- functions and operators for the built-in data types. Users can also
- define their own functions and operators, as described in the
- Programmer's Guide. The
- psql commands \df and
- \do can be used to show the list of all actually
- available functions and operators, respectively.
-
-
-
- If you are concerned about portability then take note that most of
- the functions and operators described in this chapter, with the
- exception of the most trivial arithmetic and comparison operators
- and some explicitly marked functions, are not specified by the SQL
- standard. Some of this extended functionality is present in other
- RDBMS products, and in many cases this
- functionality is compatible and consistent between various products.
-
-
-
-
- Logical Operators
-
-
- operators
- logical
+
+ functions
-
- Boolean
- operators
- operators, logical
+
+ operators
- The usual logical operators are available:
+ PostgreSQL provides a large number of
+ functions and operators for the built-in data types. Users can also
+ define their own functions and operators, as described in the
+ Programmer's Guide. The
+ psql commands \df and
+ \do can be used to show the list of all actually
+ available functions and operators, respectively.
+
-
- and
- operator
+
+ If you are concerned about portability then take note that most of
+ the functions and operators described in this chapter, with the
+ exception of the most trivial arithmetic and comparison operators
+ and some explicitly marked functions, are not specified by the
+ SQL
+ standard. Some of this extended functionality is present in other
+ RDBMS products, and in many cases this
+ functionality is compatible and consistent between various products.
+
+
+
+
+ Logical Operators
+
+
+ operators
+ logical
- or
- operator
+ Boolean
+ operators
+ operators, logical
-
- not
- operator
+
+ The usual logical operators are available:
+
+
+ and
+ operator
+
+
+
+ or
+ operator
+
+
+
+ not
+ operator
+
+
+
+ AND
+ OR
+ NOT
+
+
+ SQL uses a three-valued Boolean logic where NULL represents
+ unknown. Observe the following truth tables:
+
+
+
+
+
+ a
+ b
+ a AND b
+ a OR b
+
+
+
+
+
+ TRUE
+ TRUE
+ TRUE
+ TRUE
+
+
+
+ TRUE
+ FALSE
+ FALSE
+ TRUE
+
+
+
+ TRUE
+ NULL
+ NULL
+ TRUE
+
+
+
+ FALSE
+ FALSE
+ FALSE
+ FALSE
+
+
+
+ FALSE
+ NULL
+ FALSE
+ NULL
+
+
+
+ NULL
+ NULL
+ NULL
+ NULL
+
+
+
+
+
+
+
+
+
+ a
+ NOT a
+
+
+
+
+
+ TRUE
+ FALSE
+
+
+
+ FALSE
+ TRUE
+
+
+
+ NULL
+ NULL
+
+
+
+
+
+
+
+
+ Comparison Operators
+
+
+ comparison
+ operators
-
- AND
- OR
- NOT
-
-
- SQL uses a three-valued Boolean logic where NULL represents
- unknown. Observe the following truth tables:
-
-
-
-
-
- a
- b
- a AND b
- a OR b
-
-
-
-
-
- TRUE
- TRUE
- TRUE
- TRUE
-
-
-
- TRUE
- FALSE
- FALSE
- TRUE
-
-
-
- TRUE
- NULL
- NULL
- TRUE
-
-
-
- FALSE
- FALSE
- FALSE
- FALSE
-
-
-
- FALSE
- NULL
- FALSE
- NULL
-
-
-
- NULL
- NULL
- NULL
- NULL
-
-
-
-
-
-
+
+ Comparison Operators
- a
- NOT a
+ Operator
+ Description
- TRUE
- FALSE
+ <
+ less than
- FALSE
- TRUE
+ >
+ greater than
- NULL
- NULL
+ <=
+ less than or equal to
+
+
+
+ >=
+ greater than or equal to
+
+
+
+ =
+ equal
+
+
+
+ <> or !=
+ not equal
-
-
-
+
-
- Comparison Operators
+
+
+ The != operator is converted to
+ <> in the parser stage. It is not
+ possible to implement != and
+ <> operators that do different things.
+
+
-
- comparison
- operators
-
-
-
- Comparison Operators
-
-
-
- Operator
- Description
-
-
-
-
-
- <
- less than
-
-
-
- >
- greater than
-
-
-
- <=
- less than or equal to
-
-
-
- >=
- greater than or equal to
-
-
-
- =
- equal
-
-
-
- <> or !=
- not equal
-
-
-
-
-
-
- The != operator is converted to
- <> in the parser stage. It is not
- possible to implement != and
- <> operators that do different things.
+ Comparison operators are available for all data types where this
+ makes sense. All comparison operators are binary operators that
+ return values of type boolean; expressions like
+ 1 < 2 < 3 are not valid (because there is
+ no < operator to compare a Boolean value with
+ 3).
-
-
- Comparison operators are available for all data types where this
- makes sense. All comparison operators are binary operators that
- return values of type boolean; expressions like
- 1 < 2 < 3 are not valid (because there is
- no < operator to compare a Boolean value with
- 3).
-
-
-
-
- between
-
- In addition to the comparison operators, the special
- BETWEEN construct is available.
-
+
+
+ between
+
+ In addition to the comparison operators, the special
+ BETWEEN construct is available.
+ a BETWEEN x AND y
-
- is equivalent to
-
-a >= x AND a <= y
-
- Similarly,
-
+
+ is equivalent to
+
+a >= x AND aable> <= y
+
+ Similarly,
+ a NOT BETWEEN x AND y
-
- is equivalent to
-
-a < x OR a > y
-
- There is no difference between the two respective forms apart from
- the CPU cycles required to rewrite the first one
- into the second one internally.
-
+
+ is equivalent to
+
+a < x OR aable> > y
+
+ There is no difference between the two respective forms apart from
+ the CPU cycles required to rewrite the first one
+ into the second one internally.
+
-
- To check whether a value is or is not NULL, use the constructs
-
+
+ To check whether a value is or is not NULL, use the constructs
+ expression IS NULL
expression IS NOT NULL
-
- or the equivalent, but less standard, constructs
-
+
+ or the equivalent, but less standard, constructs
+ expression ISNULL
expression NOTNULL
-
-
+
+
-
- Do not write
- expression = NULL
- because NULL is not equal to NULL. (NULL represents
- an unknown value, and it is not known whether two unknown values are
- equal.)
-
+
+ Do not write
+ expression = NULL
+ because NULL is not equal to NULL. (NULL represents
+ an unknown value, and it is not known whether two unknown values are
+ equal.)
+
-
- Some applications may (incorrectly) require that
- expression = NULL
- returns true if expression evaluates to
- the NULL value. To support these applications, the run-time option
- transform_null_equals can be turned on (e.g.,
- SET transform_null_equals TO ON;).
- PostgreSQL will then convert x
- = NULL clauses to x IS NULL. This was
- the default behavior in releases 6.5 through 7.1.
-
+
+ Some applications may (incorrectly) require that
+ expression = NULL
+ returns true if expression evaluates to
+ the NULL value. To support these applications, the run-time option
+ transform_null_equals can be turned on (e.g.,
+ SET transform_null_equals TO ON;).
+ PostgreSQL will then convert
+ x = NULL clauses to
+ x IS NULL. This was
+ the default behavior in releases 6.5 through 7.1.
+
-
- Boolean values can also be tested using the constructs
-
+
+ Boolean values can also be tested using the constructs
+ expression IS TRUE
expression IS NOT TRUE
expression IS FALSE
expression IS NOT FALSE
expression IS UNKNOWN
expression IS NOT UNKNOWN
-
- These are similar to IS NULL in that they will
- always return TRUE or FALSE, never NULL, even when the operand is NULL.
- A NULL input is treated as the logical value UNKNOWN.
-
-
+
+ These are similar to IS NULL in that they will
+ always return TRUE or FALSE, never NULL, even when the operand is NULL.
+ A NULL input is treated as the logical value UNKNOWN.
+
+
+
+ Mathematical Functions and Operators
-
- Mathematical Functions and Operators
-
-
- Mathematical operators are provided for many
- PostgreSQL types. For types without
- common mathematical conventions for all possible permutations
- (e.g. date/time types) we
- describe the actual behavior in subsequent sections.
-
-
-
-
-
- The binary operators are also available for the bit
- string types BIT and BIT VARYING.
+
+ Mathematical operators are provided for many
+ PostgreSQL types. For types without
+ common mathematical conventions for all possible permutations
+ (e.g. date/time types) we
+ describe the actual behavior in subsequent sections.
+
- Bit string arguments to &, |,
- and # must be of equal length. When bit
- shifting, the original length of the string is preserved, as shown
- here.
-
+
+ The binary operators are also available for the bit
+ string types BIT and BIT VARYING.
-
- Mathematical Functions
-
-
-
- Function
- Return Type
- Description
- Example
- Result
-
-
+
-
- ceil(numeric)
- numeric
- smallest integer not less than argument
- ceil(-42.8)
- -42
-
+ Bit string arguments to &, |,
+ and # must be of equal length. When bit
+ shifting, the original length of the string is preserved, as shown
+ here.
+
-
- degrees(dp)
- dp
- radians to degrees
- degrees(0.5)
- 28.6478897565412
-
+
+ Mathematical Functions
+
+
+
+ Function
+ Return Type
+ Description
+ Example
+ Result
+
+
-
- exp(dp)
- dp
- exponential
- exp(1.0)
- 2.71828182845905
-
+
+
+ abs(x)
+ (same as x)
+ absolute value
+ abs(-17.4)
+ 17.4
+
-
- floor(numeric)
- numeric
- largest integer not greater than argument
- floor(-42.8)
- -43
-
+
+ cbrt(dp)
+ dp
+ cube root
+ cbrt(27.0)
+ 3
+
-
- ln(dp)
- dp
- natural logarithm
- ln(2.0)
- 0.693147180559945
-
+
+ ceil(numeric)
+ numeric
+ smallest integer not less than argument
+ ceil(-42.8)
+ -42
+
-
- log(dp)
- dp
- base 10 logarithm
- log(100.0)
- 2
-
+
+ degrees(dp)
+ dp
+ radians to degrees
+ degrees(0.5)
+ 28.6478897565412
+
-
- log(bnumeric,
- xnumeric)
- numeric
- logarithm to base b
- log(2.0, 64.0)
- 6.0000000000
-
+
+ exp(dp)
+ dp
+ exponential
+ exp(1.0)
+ 2.71828182845905
+
-
- mod(y, x)
- (same as argument types)
- remainder of y/x
- mod(9,4)
- 1
-
+
+ floor(numeric)
+ numeric
+ largest integer not greater than argument
+ floor(-42.8)
+ -43
+
-
- pi()
- dp
- Pi constant
- pi()
- 3.14159265358979
-
+
+ ln(dp)
+ dp
+ natural logarithm
+ ln(2.0)
+ 0.693147180559945
+
-
- pow(edp,
- ndp)
- dp
- raise a number to exponent e
- pow(9.0, 3.0)
- 729
-
+
+ log(dp)
+ dp
+ base 10 logarithm
+ log(100.0)
+ 2
+
-
- radians(dp)
- dp
- degrees to radians
- radians(45.0)
- 0.785398163397448
-
+
+ log(bnumeric,
+ xnumeric)
+ numeric
+ logarithm to base b
+ log(2.0, 64.0)
+ 6.0000000000
+
-
- random()
- dp
- value between 0.0 to 1.0
- random()
-
-
+
+ mod(y,
+ x)
+ (same as argument types)
+ remainder of y/x
+ mod(9,4)
+ 1
+
-
- round(dp)
- dp
- round to nearest integer
- round(42.4)
- 42
-
+
+ pi()
+ dp
+ Pi constant
+ pi()
+ 3.14159265358979
+
-
- round(vnumeric, sinteger)
- numeric
- round to s decimal places
- round(42.4382, 2)
- 42.44
-
+
+ pow(edp,
+ ndp)
+ dp
+ raise a number to exponent e
+ pow(9.0, 3.0)
+ 729
+
+
+
+ radians(dp)
+ dp
+ degrees to radians
+ radians(45.0)
+ 0.785398163397448
+
+
+
+ random()
+ dp
+ value between 0.0 to 1.0
+ random()
+
+
+
+
+ round(dp)
+ dp
+ round to nearest integer
+ round(42.4)
+ 42
+
+
+
+ round(vnumeric, sinteger)
+ numeric
+ round to s decimal places
+ round(42.4382, 2)
+ 42.44
+
-
- sign(numeric)
- numeric
- sign of the argument (-1, 0, +1)
- sign(-8.4)
- -1
-
+
+ sign(numeric)
+ numeric
+ sign of the argument (-1, 0, +1)
+ sign(-8.4)
+ -1
+
-
- sqrt(dp)
- dp
- square root
- sqrt(2.0)
- 1.4142135623731
-
+
+ sqrt(dp)
+ dp
+ square root
+ sqrt(2.0)
+ 1.4142135623731
+
-
- trunc(dp)
- dp
- truncate toward zero
- trunc(42.8)
- 42
-
+
+ trunc(dp)
+ dp
+ truncate toward zero
+ trunc(42.8)
+ 42
+
-
- trunc(numeric, sinteger)
- numeric
- truncate to s decimal places
- trunc(42.4382, 2)
- 42.43
-
+
+ trunc(numeric,
+ rrameter> integer)
+ numeric
+ truncate to s decimal places
+ trunc(42.4382, 2)
+ 42.43
+
-
-
-
+
+
+
-
- In the table above, dp indicates double precision.
- The functions exp, ln,
- log, pow,
- round (1 argument), sqrt,
- and trunc (1 argument) are also available for
- the type numeric in place of double
- precision.
- Functions returning a numeric result take
- numeric input arguments, unless otherwise specified.
- Many of these functions are implemented on top
- of the host system's C library; accuracy and behavior in boundary cases
- could therefore vary depending on the host system.
-
+
+ In the table above, dp indicates double precision.
+ The functions exp, ln,
+ log, pow,
+ round (1 argument), sqrt,
+ and trunc (1 argument) are also available for
+ the type numeric in place of
+ double precision.
+ Functions returning a numeric result take
+ numeric input arguments, unless otherwise specified.
+ Many of these functions are implemented on top
+ of the host system's C library; accuracy and behavior in boundary cases
+ could therefore vary depending on the host system.
+
-
-
- All trigonometric functions have arguments and return values of
- type double precision.
-
+
+ All trigonometric functions have arguments and return values of
+ type double precision.
+
-
+
-
- String Functions and Operators
+
+ String Functions and Operators
-
- This section describes functions and operators for examining and
- manipulating string values. Strings in this context include values
- of all the types CHARACTER, CHARACTER
- VARYING, and TEXT. Unless otherwise noted, all
- of the functions listed below work on all of these types, but be
- wary of potential effects of the automatic padding when using the
- CHARACTER type. Generally, the functions described
- here also work on data of non-string types by converting that data
- to a string representation first. Some functions also exist
- natively for bit-string types.
-
+
+ This section describes functions and operators for examining and
+ manipulating string values. Strings in this context include values
+ of all the types CHARACTER, CHARACTER
+ VARYING, and TEXT. Unless otherwise noted, all
+ of the functions listed below work on all of these types, but be
+ wary of potential effects of the automatic padding when using the
+ CHARACTER type. Generally, the functions described
+ here also work on data of non-string types by converting that data
+ to a string representation first. Some functions also exist
+ natively for bit-string types.
+
-
- SQL defines some string functions with a special syntax where
- certain keywords rather than commas are used to separate the
- arguments. Details are in .
- These functions are also implemented using the regular syntax for
- function invocation. (See .)
-
+
+ SQL defines some string functions with a special syntax where
+ certain keywords rather than commas are used to separate the
+ arguments. Details are in .
+ These functions are also implemented using the regular syntax for
+ function invocation. (See .)
+
-
- SQL String Functions and Operators
-
-
-
- Function
- Return Type
- Description
- Example
- Result
-
-
+
+ SQL String Functions and Operators
+
+
+
+ Function
+ Return Type
+ Description
+ Example
+ Result
+
+
-
-
- string||string
- text
-
- string concatenation
-
- character strings
- concatenation
-
-
- 'Postgre' || 'SQL'>
- PostgreSQL>
-
+
+
+ string||
+ string
+ text
+
+ string concatenation
+
+ character strings
+ concatenation
+
+
+ 'Postgre' || 'SQL'
+ PostgreSQL
+
-
- bit_length(string)
- integer
- number of bits in string
- bit_length('jose')
- 32
-
+
+ bit_length(string)
+ integer
+ number of bits in string
+ bit_length('jose')
+ 32
+
-
- char_length(string) or character_length(string)
- integer
-
- number of characters in string
-
- character strings
- length
-
-
- length
- character strings
- character strings, length
-
-
- char_length('jose')>
- 4>
-
+
+ char_length(string) or character_length(string)
+ integer
+
+ number of characters in string
+
+ character strings
+ length
+
+
+ length
+ character strings
+ character strings, length
+
+
+ char_length('jose')
+ 4
+
-
- lower(string)
- text
- Convert string to lower case.
- lower('TOM')
- tom
-
+
+ lower(string)
+ text
+ Convert string to lower case.
+ lower('TOM')
+ tom
+
-
- octet_length(string)
- integer
- number of bytes in string
- octet_length('jose')
- 4
-
+
+ octet_length(string)
+ integer
+ number of bytes in string
+ octet_length('jose')
+ 4
+
-
- position(substring in string)
- integer
- location of specified substring
- position('om' in 'Thomas')
- 3
-
+
+ overlay(string placing string from integerfor integer)
+ text
+
+ insert substring
+
+ overlay
+
+
+ overlay('Txxxxas' placing 'hom' from 2 for 4)
+ Thomas
+
-
- substring(stringfrom integerfor integer)
- text
-
- extract substring
-
- substring
-
-
- substring('Thomas' from 2 for 3)
- hom
-
+
+ position(substring in string)
+ integer
+ location of specified substring
+ position('om' in 'Thomas')
+ 3
+
-
-
- trim(leading | trailing | both
- characters from
- string)
-
- text
-
- Removes the longest string containing only the
- characters (a space by default) from the
- beginning/end/both ends of the string.
-
- trim(both 'x' from 'xTomxx')
- Tom
-
+
+ substring(stringfrom integerfor integer)
+ text
+
+ extract substring
+
+ substring
+
+
+ substring('Thomas' from 2 for 3)
+ hom
+
-
- upper(string)
- text
- Convert string to upper case.
- upper('tom')
- TOM
-
-
-
-
+
+ substring(stringfrom patternfor escape)
+ text
+
+ extract regular expression
+
+ substring
+
+
+ substring('Thomas' from 'mas$' for escape '\\')
+ mas
+
-
- Additional string manipulation functions are available and are
- listed below. Some of them are used internally to implement the
- SQL-standard string functions listed above.
-
+
+
+ trim(leading | trailing | both
+ characters from
+ string)
+
+ text
+
+ Removes the longest string containing only the
+ characters (a space by default) from the
+ beginning/end/both ends of the string.
+
+ trim(both 'x' from 'xTomxx')
+ Tom
+
-
- Other String Functions
-
-
-
- Function
- Return Type
- Description
- Example
- Result
-
-
+
+ upper(string)
+ text
+ Convert string to upper case.
+ upper('tom')
+ TOM
+
+
+
+
-
-
- ascii(text)
- integer
- Returns the ASCII code of the first character of the argument.
- ascii('x')
- 120
-
+
+ Additional string manipulation functions are available and are
+ listed below. Some of them are used internally to implement the
+ SQL-standard string functions listed above.
+
-
- btrim(stringtext, trimtext)
- text
-
- Remove (trim) the longest string consisting only of characters
- in trim from the start and end of
- string.
-
- btrim('xyxtrimyyx','xy')
- trim
-
+
+ Other String Functions
+
+
+
+ Function
+ Return Type
+ Description
+ Example
+ Result
+
+
-
- chr(integer)
- text
- Returns the character with the given ASCII code.
- chr(65)
- A
-
+
+
+ ascii(text)
+ integer
+ Returns the ASCII code of the first character of the argument.
+ ascii('x')
+ 120
+
-
-
- convert(stringtext,
- src_encodingname,
- dest_encodingname)
-
- text
-
- Converts string using dest_encoding.
- The original encoding is specified by
- src_encoding. If
- src_encoding is omitted, database
- encoding is assumed.
-
- convert('text_in_unicode', 'UNICODE', 'LATIN1')
- text_in_unicode represented in ISO 8859-1
-
+
+ btrim(stringtext, trimtext)
+ text
+
+ Remove (trim) the longest string consisting only of characters
+ in trim from the start and end of
+ string.
+
+ btrim('xyxtrimyyx','xy')
+ trim
+
-
- initcap(text)
- text
- Converts first letter of each word (whitespace separated) to upper case.
- initcap('hi thomas')
- Hi Thomas
-
+
+ chr(integer)
+ text
+ Returns the character with the given ASCII code.
+ chr(65)
+ A
+
-
- length(string)
- integer
-
- length of string
-
- character strings
- length
-
-
- length
- character strings
- character strings, length
-
-
- length('jose')>
- 4>
-
+
+
+ convert(string
+ text,
+ src_encodingname,
+ dest_encodingname)
+
+ text
+
+ Converts string using dest_encoding.
+ The original encoding is specified by
+ src_encoding. If
+ src_encoding is omitted, database
+ encoding is assumed.
+
+ convert('text_in_unicode', 'UNICODE', 'LATIN1')
+ text_in_unicode represented in ISO 8859-1
+
-
-
- lpad(stringtext,
- lengthinteger
- , filltext)
-
- text
-
- Fills up the string to length
- length by prepending the characters
- fill (a space by default). If the
- string is already longer than
- length then it is truncated (on the
- right).
-
- lpad('hi', 5, 'xy')
- xyxhi
-
+
+ initcap(text)
+ text
+ Converts first letter of each word (whitespace separated) to upper case.
+ initcap('hi thomas')
+ Hi Thomas
+
-
- ltrim(stringtext, trimtext)
- text
-
- Removes the longest string containing only characters from
- trim from the start of the string.
-
- ltrim('zzzytrim','xyz')
- trim
-
+
+ length(string)
+ integer
+
+ length of string
+
+ character strings
+ length
+
+
+ length
+ character strings
+ character strings, length
+
+
+ length('jose')
+ 4
+
-
- pg_client_encoding()
- name
-
- Returns current client encoding name.
-
- pg_client_encoding()
- SQL_ASCII
-
+
+
+ lpad(stringtext,
+ lengthinteger
+ , filltext)
+
+ text
+
+ Fills up the string to length
+ length by prepending the characters
+ fill (a space by default). If the
+ string is already longer than
+ length then it is truncated (on the
+ right).
+
+ lpad('hi', 5, 'xy')
+ xyxhi
+
-
- repeat(text, integer)
- text
- Repeat text a number of times.
- repeat('Pg', 4)
- PgPgPgPg
-
+
+ ltrim(stringtext, texttext)
+ text
+
+ Removes the longest string containing only characters from
+ trim from the start of the string.
+
+ ltrim('zzzytrim','xyz')
+ trim
+
-
-
- rpad(stringtext,
- lengthinteger
- , filltext)
-
- text
-
- Fills up the string to length
- length by appending the characters
- fill (a space by default). If the
- string is already longer than
- length then it is truncated.
-
- rpad('hi', 5, 'xy')
- hixyx
-
+
+ pg_client_encoding()
+ name
+
+ Returns current client encoding name.
+
+ pg_client_encoding()
+ SQL_ASCII
+
-
- rtrim(string text, trim text)
- text
-
- Removes the longest string containing only characters from
- trim from the end of the string.
-
- rtrim('trimxxxx','x')
- trim
-
+
+ repeat(text, integer)
+ text
+ Repeat text a number of times.
+ repeat('Pg', 4)
+ PgPgPgPg
+
-
- strpos(string, substring)
- text
-
- Locates specified substring. (same as
- position(substring in
- string), but note the reversed
- argument order)
-
- strpos('high','ig')
- 2
-
+
+
+ rpad(stringtext,
+ lengthinteger
+ , filltext)
+
+ text
+
+ Fills up the string to length
+ length by appending the characters
+ fill (a space by default). If the
+ string is already longer than
+ length then it is truncated.
+
+ rpad('hi', 5, 'xy')
+ hixyx
+
-
- substr(string, from, count)
- text
-
- Extracts specified substring. (same as substring(string from from for count))
-
- substr('alphabet', 3, 2)
- ph
-
+
+ rtrim(string
+ text, trim text)
+ text
+
+ Removes the longest string containing only characters from
+ trim from the end of the string.
+
+ rtrim('trimxxxx','x')
+ trim
+
-
- to_ascii(text, encoding)
- text
- Converts text from multibyte encoding to ASCII.
- to_ascii('Karel')
- Karel
-
+
+ strpos(string, substring)
+ text
+
+ Locates specified substring. (same as
+ position(substring in
+ string), but note the reversed
+ argument order)
+
+ strpos('high','ig')
+ 2
+
-
-
- translate(stringtext,
- fromtext,
- totext)
-
- text
-
- Any character in string that matches a
- character in the from set is replaced by
- the corresponding character in the to
- set.
-
- translate('12345', '14', 'ax')
- a23x5
-
-
-
-
- encode(databytea,
- typetext)
-
- text
-
- Encodes binary data to ASCII-only representation. Supported
- types are: 'base64', 'hex', 'escape'.
-
- encode('123\\000\\001', 'base64')
- MTIzAAE=
-
+
+ substr(string, from, count)
+ text
+
+ Extracts specified substring. (same as
+ substring(string from from for count))
+
+ substr('alphabet', 3, 2)
+ ph
+
-
-
- decode(stringtext,
- typetext)
-
- bytea
-
- Decodes binary data from string previously
- encoded with encode(). Parameter type is same as in encode().
-
- decode('MTIzAAE=', 'base64')
- 123\000\001
-
+
+ to_ascii(text
+ ptional>, encoding)
+ text
+ Converts text from multibyte encoding to ASCII.
+ to_ascii('Karel')
+ Karel
+
-
-
-
+
+
+ translate(string
+ text,
+ fromtext,
+ totext)
+
+ text
+
+ Any character in string that matches a
+ character in the from set is replaced by
+ the corresponding character in the to
+ set.
+
+ translate('12345', '14', 'ax')
+ a23x5
+
+
+
+
+ encode(databytea,
+ typetext)
+
+ text
+
+ Encodes binary data to ASCII-only representation. Supported
+ types are: 'base64', 'hex', 'escape'.
+
+ encode('123\\000\\001', 'base64')
+ MTIzAAE=
+
-
- The to_ascii function supports conversion from
- LATIN1, LATIN2, WIN1250 (CP1250) only.
-
-
+
+
+ decode(stringtext,
+ typetext)
+
+ bytea
+
+ Decodes binary data from string previously
+ encoded with encode(). Parameter type is same as in encode().
+
+ decode('MTIzAAE=', 'base64')
+ 123\000\001
+
+
+
+
+
+
+
+ The to_ascii function supports conversion from
+ LATIN1, LATIN2, WIN1250 (CP1250) only.
+
+
-
- Binary String Functions and Operators
+
+ Binary String Functions and Operators
-
- This section describes functions and operators for examining and
- manipulating binary string values. Strings in this context include
- values of the type BYTEA.
-
+
+ This section describes functions and operators for examining and
+ manipulating binary string values. Strings in this context include
+ values of the type BYTEA.
+
-
- SQL defines some string functions with a special syntax where
- certain keywords rather than commas are used to separate the
- arguments. Details are in .
- Some functions are also implemented using the regular syntax for
- function invocation. (See .)
-
+
+ SQL defines some string functions with a
+ special syntax where
+ certain keywords rather than commas are used to separate the
+ arguments. Details are in
+ .
+ Some functions are also implemented using the regular syntax for
+ function invocation.
+ (See .)
+
-
- SQL Binary String Functions and Operators
-
-
-
- Function
- Return Type
- Description
- Example
- Result
-
-
+
+ SQL Binary String Functions and Operators
+
+
+
+ Function
+ Return Type
+ Description
+ Example
+ Result
+
+
-
-
- string||string
- bytea
-
- string concatenation
-
- binary strings
- concatenation
-
-
- '\\\\Postgre'::bytea || '\\047SQL\\000'::bytea>
- \\Postgre'SQL\000>
-
+
+
+ string||
+ string
+ bytea
+
+ string concatenation
+
+ binary strings
+ concatenation
+
+
+ '\\\\Postgre'::bytea || '\\047SQL\\000'::bytea
+ \\Postgre'SQL\000
+
-
- octet_length(string)
- integer
- number of bytes in binary string
- octet_length('jo\\000se'::bytea)
- 5
-
+
+ octet_length(string)
+ integer
+ number of bytes in binary string
+ octet_length('jo\\000se'::bytea)
+ 5
+
-
- position(substring in string)
- integer
- location of specified substring
+
+ position(substring in string)
+ integer
+ location of specified substringposition('\\000om'::bytea in 'Th\\000omas'::bytea)
- 3
-
+ 3
+
-
- substring(stringfrom integerfor integer)
- bytea
-
- extract substring
-
- substring
-
-
- substring('Th\\000omas'::bytea from 2 for 3)
- h\000o
-
+
+ substring(stringfrom integerfor integer)
+ bytea
+
+ extract substring
+
+ substring
+
+
+ substring('Th\\000omas'::bytea from 2 for 3)
+ h\000o
+
-
-
- trim(both
- characters from
- string)
-
- bytea
-
- Removes the longest string containing only the
- characters from the
- beginning/end/both ends of the string.
-
- trim('\\000'::bytea from '\\000Tom\\000'::bytea)
- Tom
-
+
+
+ trim(both
+ characters from
+ string)
+
+ bytea
+
+ Removes the longest string containing only the
+ characters from the
+ beginning/end/both ends of the string.
+
+ trim('\\000'::bytea from '\\000Tom\\000'::bytea)
+ Tom
+
+
+
+
-
-
-
+
+ Additional binary string manipulation functions are available and are
+ listed below. Some of them are used internally to implement the
+ SQL-standard string functions listed above.
+
-
- Additional binary string manipulation functions are available and are
- listed below. Some of them are used internally to implement the
- SQL-standard string functions listed above.
-
+
+ Other Binary String Functions
+
+
+
+ Function
+ Return Type
+ Description
+ Example
+ Result
+
+
-
- Other Binary String Functions
-
-
-
- Function
- Return Type
- Description
- Example
- Result
-
-
-
-
-
- btrim(stringbytea, trimbytea)
- bytea
-
- Remove (trim) the longest string consisting only of characters
- in trim from the start and end of
- string.
+
+
+ btrim(string
+ byteatrimbytea)
+ bytea
+
+ Remove (trim) the longest string consisting only of characters
+ in trim from the start and end of
+ string.
btrim('\\000trim\\000'::bytea,'\\000'::bytea)trim
@@ -1313,8 +1354,8 @@ PostgreSQL documentation
binary strings, length
- length('jo\\000se'::bytea)>
- 5>
+ length('jo\\000se'::bytea)
+ 5
@@ -1355,66 +1396,78 @@ PostgreSQL documentation
Pattern Matching
-
- There are two separate approaches to pattern matching provided by
- PostgreSQL: the SQL
- LIKE operator and
- POSIX-style regular expressions.
-
-
-
- If you have pattern matching needs that go beyond this, or want to
- make pattern-driven substitutions or translations, consider
- writing a user-defined function in Perl or Tcl.
+ There are two separate approaches to pattern matching provided by
+ PostgreSQL: the traditional
+ SQL
+ LIKE operator and the more recent
+ SQL99
+ SIMILAR TO operator implementing
+ POSIX-style regular expressions.
+ Additionally, a pattern matching function,
+ SUBSTRING, is available, as defined in
+ SQL99.
+
+
+
+
+ If you have pattern matching needs that go beyond this,
+ consider writing a user-defined function in Perl or Tcl.
+
+
+
+
+ Both LIKE and SIMILAR TO
+ are SQL-standard operators which are also available in alternate
+ forms as PostgreSQL operators; look at
+ ~ and ~~ for examples.
-
- Pattern Matching with LIKE
+ LIKElike
-
-string LIKE pattern ESCAPE escape-character
-string NOT LIKE pattern ESCAPE escape-character
-
+
+string LIKE patternESCAPE escape-character
+string NOT LIKE patternESCAPE escape-character
+
-
- Every pattern defines a set of strings.
- The LIKE expression returns true if the
- string is contained in the set of
- strings represented by pattern. (As
- expected, the NOT LIKE expression returns
- false if LIKE returns true, and vice versa.
- An equivalent expression is NOT
- (string LIKE
- pattern).)
-
-
-
- If pattern does not contain percent
- signs or underscore, then the pattern only represents the string
- itself; in that case LIKE acts like the
- equals operator. An underscore (_) in
- pattern stands for (matches) any single
- character; a percent sign (%) matches any string
- of zero or more characters.
-
-
-
- Some examples:
-
+ Every pattern defines a set of strings.
+ The LIKE expression returns true if the
+ string is contained in the set of
+ strings represented by pattern. (As
+ expected, the NOT LIKE expression returns
+ false if LIKE returns true, and vice versa.
+ An equivalent expression is
+ NOT (string LIKE
+ pattern).)
+
+
+
+ If pattern does not contain percent
+ signs or underscore, then the pattern only represents the string
+ itself; in that case LIKE acts like the
+ equals operator. An underscore (_) in
+ pattern stands for (matches) any single
+ character; a percent sign (%) matches any string
+ of zero or more characters.
+
+
+
+
+ Some examples:
+
'abc' LIKE 'abc' true
'abc' LIKE 'a%' true
'abc' LIKE '_b_' true
'abc' LIKE 'c' false
-
-
-
+
+
+ LIKE pattern matches always cover the entire
@@ -1439,14 +1492,15 @@ PostgreSQL documentation
that actually matches a literal backslash means writing four backslashes
in the query. You can avoid this by selecting a different escape
character with ESCAPE; then backslash is not special
- to LIKE> anymore. (But it is still special to the string
+ to LIKE anymore. (But it is still special to the string
literal parser, so you still need two of them.)
It's also possible to select no escape character by writing
- ESCAPE ''. In this case there is no way to
- turn off the special meaning of underscore and percent signs in
+ ESCAPE ''. This effectively disables the
+ escape mechanism and
+ turns off the special meaning of underscore and percent signs in
the pattern.
@@ -1470,7 +1524,8 @@ PostgreSQL documentation
- POSIX Regular Expressions
+ SIMILAR TO and POSIX
+ Regular Expressionsregular expressions
@@ -1489,58 +1544,80 @@ PostgreSQL documentation
-
-
- ~
- Matches regular expression, case sensitive
- 'thomas' ~ '.*thomas.*'
-
-
- ~*
- Matches regular expression, case insensitive
- 'thomas' ~* '.*Thomas.*'
-
-
- !~
- Does not match regular expression, case sensitive
- 'thomas' !~ '.*Thomas.*'
-
-
- !~*
- Does not match regular expression, case insensitive
- 'thomas' !~* '.*vadim.*'
-
-
-
-
+
+
+ ~
+ Matches regular expression, case sensitive
+ 'thomas' ~ '.*thomas.*'
+
-
- POSIX regular expressions provide a more powerful means for
- pattern matching than the LIKE function.
- Many Unix tools such as egrep,
- sed, or awk use a pattern
- matching language that is similar to the one described here.
-
+
+ ~*
+ Matches regular expression, case insensitive
+ 'thomas' ~* '.*Thomas.*'
+
-
- A regular expression is a character sequence that is an
- abbreviated definition of a set of strings (a regular
- set). A string is said to match a regular expression
- if it is a member of the regular set described by the regular
- expression. As with LIKE, pattern characters
- match string characters exactly unless they are special characters
- in the regular expression language --- but regular expressions use
- different special characters than LIKE does.
- Unlike LIKE patterns, a
- regular expression is allowed to match anywhere within a string, unless
- the regular expression is explicitly anchored to the beginning or
- end of the string.
-
+
+ !~
+ Does not match regular expression, case sensitive
+ 'thomas' !~ '.*Thomas.*'
+
+
+ !~*
+ Does not match regular expression, case insensitive
+ 'thomas' !~* '.*vadim.*'
+
+
+
+ SIMILAR TO
+ Matches regular expression, case sensitive
+ 'thomas' SIMILAR TO '.*thomas.*'
+
+
+
+
+
+
+ POSIX regular expressions provide a more
+ powerful means for
+ pattern matching than the LIKE function.
+ Many Unix tools such as egrep,
+ sed, or awk use a pattern
+ matching language that is similar to the one described here.
+
+
+
+ A regular expression is a character sequence that is an
+ abbreviated definition of a set of strings (a regular
+ set). A string is said to match a regular expression
+ if it is a member of the regular set described by the regular
+ expression. As with LIKE, pattern characters
+ match string characters exactly unless they are special characters
+ in the regular expression language --- but regular expressions use
+ different special characters than LIKE does.
+ Unlike LIKE patterns, a
+ regular expression is allowed to match anywhere within a string, unless
+ the regular expression is explicitly anchored to the beginning or
+ end of the string.
+
+
+
+
+ Some examples:
+
+'abc' SIMILAR TO 'abc' true
+'abc' SIMILAR TO '^a' true
+'abc' SIMILAR TO '(b|d)' true
+'abc' SIMILAR TO '^(b|c)' false
+
+
+
- Regular expressions (REs), as defined in POSIX
+ Regular expressions (REs), as defined in
+ POSIX
1003.2, come in two forms: modern REs (roughly those of
egrep; 1003.2 calls these
extended REs) and obsolete REs (roughly those of
@@ -1834,7 +1911,8 @@ PostgreSQL documentation
to_char(125, '999')
- to_char(double precision, text)
+ to_char(double precision,
+ text)textconvert real/double precision to stringto_char(125.8, '999D9')
@@ -1919,11 +1997,13 @@ PostgreSQL documentation
seconds past midnight (0-86399)
- AM or A.M. or PM or P.M.
+ AM or A.M. or
+liliteral> or P.M.meridian indicator (upper case)
- am or a.m. or pm or p.m.
+ am or a.m. or
+liliteral> or p.m.meridian indicator (lower case)
@@ -1947,11 +2027,13 @@ PostgreSQL documentation
last digit of year
- BC or B.C. or AD or A.D.
+ BC or B.C. or
+liliteral> or A.D.era indicator (upper case)
- bc or b.c. or ad or a.d.
+ bc or b.c. or
+liliteral> or a.d.era indicator (lower case)
@@ -2185,10 +2267,10 @@ PostgreSQL documentation
seconds after the decimal point. For example
to_timestamp('12:3', 'SS:MS') is not 3 milliseconds,
but 300, because the conversion counts it as 12 + 0.3.
- This means for the format SS:MS>, the input values
- 12:3>, 12:30>, and 12:300> specify the
+ This means for the format SS:MS, the input values
+ 12:3, 12:30, and 12:300 specify the
same number of milliseconds. To get three milliseconds, one must use
- 12:003>, which the conversion counts as
+ 12:003, which the conversion counts as
12 + 0.003 = 12.003 seconds.
@@ -2288,11 +2370,11 @@ PostgreSQL documentation
- A sign formatted using SG>, PL>, or
- MI> is not an anchor in
+ A sign formatted using SG, PL, or
+ MI is not an anchor in
the number; for example,
- to_char(-12, 'S9999')> produces ' -12',
- but to_char(-12, 'MI9999')> produces '- 12'.
+ to_char(-12, 'S9999') produces ' -12',
+ but to_char(-12, 'MI9999') produces '- 12'.
The Oracle implementation does not allow the use of
MI ahead of 9, but rather
requires that 9 precede
@@ -2497,9 +2579,9 @@ PostgreSQL documentation
behaviors of the basic arithmetic
operators (+, *, etc.).
For formatting functions, refer to . You should be familiar with the
+ linkend="functions-formatting">. You should be familiar with the
background information on date/time data types (see ).
+ linkend="datatype-datetime">).
@@ -2614,8 +2696,7 @@ PostgreSQL documentation
current_datedate
- Today's date; see below
+ Today's date; see below
@@ -2624,8 +2705,7 @@ PostgreSQL documentation
current_timetime
- Time of day; see below
+ Time of day; see below
@@ -2634,8 +2714,7 @@ PostgreSQL documentation
current_timestamptimestamp
- Date and time; see below
+ Date and time; see below
@@ -2646,7 +2725,7 @@ PostgreSQL documentation
double precisionGet subfield (equivalent to
extract); see also below
+ linkend="functions-datetime-datepart">below
date_part('hour', timestamp '2001-02-16 20:38:40')20
@@ -2657,7 +2736,7 @@ PostgreSQL documentation
double precisionGet subfield (equivalent to
extract); see also below
+ linkend="functions-datetime-datepart">below
date_part('month', interval '2 years 3 months')3
@@ -2667,27 +2746,29 @@ PostgreSQL documentation
date_trunc(text, timestamp)timestampTruncate to specified precision; see also below
+ linkend="functions-datetime-trunc">below
date_trunc('hour', timestamp '2001-02-16 20:38:40')2001-02-16 20:00:00+00
- extract(field from timestamp)
+ extract(field from
+ timestamp)double precisionGet subfield; see also below
+ linkend="functions-datetime-extract">below
extract(hour from timestamp '2001-02-16 20:38:40')20
- extract(field from interval)
+ extract(field from
+ interval)double precisionGet subfield; see also below
+ linkend="functions-datetime-extract">below
extract(month from interval '2 years 3 months')3
@@ -2714,7 +2795,7 @@ PostgreSQL documentation
timestampCurrent date and time (equivalent to
current_timestamp); see below
+ linkend="functions-datetime-current">below
@@ -2724,7 +2805,7 @@ PostgreSQL documentation
timeofday()textCurrent date and time; see below
+ linkend="functions-datetime-current">below
timeofday()Wed Feb 21 17:01:13.000126 2001 EST
@@ -3187,8 +3268,8 @@ SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40');
CURRENT_DATE
CURRENT_TIME
CURRENT_TIMESTAMP
-CURRENT_TIME ( precision> )
-CURRENT_TIMESTAMP ( precision> )
+CURRENT_TIME ( precision )
+CURRENT_TIMESTAMP ( precision )
CURRENT_TIME and
CURRENT_TIMESTAMP can optionally be given
@@ -3199,7 +3280,7 @@ CURRENT_TIMESTAMP ( precision> )
- Prior to PostgreSQL> 7.2, the precision parameters
+ Prior to PostgreSQL 7.2, the precision parameters
were unimplemented, and the result was always given in integer
seconds.
@@ -3209,7 +3290,7 @@ CURRENT_TIMESTAMP ( precision> )
The SQL99 standard requires these functions to
be written without any parentheses, unless a precision parameter
- is given. As of PostgreSQL> 7.2, an empty pair of
+ is given. As of PostgreSQL 7.2, an empty pair of
parentheses can be written, but this is deprecated and may be
removed in a future release.
@@ -3259,7 +3340,7 @@ SELECT timeofday();
All the date/time data types also accept the special literal value
- now> to specify the current date and time. Thus,
+ now to specify the current date and time. Thus,
the following three all return the same result:
SELECT CURRENT_TIMESTAMP;
@@ -3269,7 +3350,7 @@ SELECT TIMESTAMP 'now';
You do not want to use the third form when specifying a DEFAULT
- value while creating a table. The system will convert now>
+ value while creating a table. The system will convert now
to a timestamp as soon as the constant is parsed, so that when
the default value is needed,
the time of the table creation would be used! The first two
@@ -3294,139 +3375,139 @@ SELECT TIMESTAMP 'now';
- Geometric Operators
-
-
-
- Operator
- Description
- Usage
-
-
-
-
- +
- Translation
- box '((0,0),(1,1))' + point '(2.0,0)'
-
-
- -
- Translation
- box '((0,0),(1,1))' - point '(2.0,0)'
-
-
- *
- Scaling/rotation
- box '((0,0),(1,1))' * point '(2.0,0)'
-
-
- /
- Scaling/rotation
- box '((0,0),(2,2))' / point '(2.0,0)'
-
-
- #
- Intersection
- '((1,-1),(-1,1))' # '((1,1),(-1,-1))'
-
-
- #
- Number of points in polygon
- # '((1,0),(0,1),(-1,0))'
-
-
- ##
- Point of closest proximity
- point '(0,0)' ## lseg '((2,0),(0,2))'
-
-
- &&
- Overlaps?
- box '((0,0),(1,1))' && box '((0,0),(2,2))'
-
-
- &<
- Overlaps to left?
- box '((0,0),(1,1))' &< box '((0,0),(2,2))'
-
-
- &>
- Overlaps to right?
- box '((0,0),(3,3))' &> box '((0,0),(2,2))'
-
-
- <->
- Distance between
- circle '((0,0),1)' <-> circle '((5,0),1)'
-
-
- <<
- Left of?
- circle '((0,0),1)' << circle '((5,0),1)'
-
-
- <^
- Is below?
- circle '((0,0),1)' <^ circle '((0,5),1)'
-
-
- >>
- Is right of?
- circle '((5,0),1)' >> circle '((0,0),1)'
-
-
- >^
- Is above?
- circle '((0,5),1)' >^ circle '((0,0),1)'
-
-
- ?#
- Intersects or overlaps
- lseg '((-1,0),(1,0))' ?# box '((-2,-2),(2,2))'
-
-
- ?-
- Is horizontal?
- point '(1,0)' ?- point '(0,0)'
-
-
- ?-|
- Is perpendicular?
- lseg '((0,0),(0,1))' ?-| lseg '((0,0),(1,0))'
-
-
- @-@
- Length or circumference
- @-@ path '((0,0),(1,0))'
-
-
- ?|
- Is vertical?
- point '(0,1)' ?| point '(0,0)'
-
-
- ?||
- Is parallel?
- lseg '((-1,0),(1,0))' ?|| lseg '((-1,2),(1,2))'
-
-
- @
- Contained or on
- point '(1,1)' @ circle '((0,0),2)'
-
-
- @@
- Center of
- @@ circle '((0,0),10)'
-
-
- ~=
- Same as
- polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'
-
-
-
-
+ Geometric Operators
+
+
+
+ Operator
+ Description
+ Usage
+
+
+
+
+ +
+ Translation
+ box '((0,0),(1,1))' + point '(2.0,0)'
+
+
+ -
+ Translation
+ box '((0,0),(1,1))' - point '(2.0,0)'
+
+
+ *
+ Scaling/rotation
+ box '((0,0),(1,1))' * point '(2.0,0)'
+
+
+ /
+ Scaling/rotation
+ box '((0,0),(2,2))' / point '(2.0,0)'
+
+
+ #
+ Intersection
+ '((1,-1),(-1,1))' # '((1,1),(-1,-1))'
+
+
+ #
+ Number of points in polygon
+ # '((1,0),(0,1),(-1,0))'
+
+
+ ##
+ Point of closest proximity
+ point '(0,0)' ## lseg '((2,0),(0,2))'
+
+
+ &&
+ Overlaps?
+ box '((0,0),(1,1))' && box '((0,0),(2,2))'
+
+
+ &<
+ Overlaps to left?
+ box '((0,0),(1,1))' &< box '((0,0),(2,2))'
+
+
+ &>
+ Overlaps to right?
+ box '((0,0),(3,3))' &> box '((0,0),(2,2))'
+
+
+ <->
+ Distance between
+ circle '((0,0),1)' <-> circle '((5,0),1)'
+
+
+ <<
+ Left of?
+ circle '((0,0),1)' << circle '((5,0),1)'
+
+
+ <^
+ Is below?
+ circle '((0,0),1)' <^ circle '((0,5),1)'
+
+
+ >>
+ Is right of?
+ circle '((5,0),1)' >> circle '((0,0),1)'
+
+
+ >^
+ Is above?
+ circle '((0,5),1)' >^ circle '((0,0),1)'
+
+
+ ?#
+ Intersects or overlaps
+ lseg '((-1,0),(1,0))' ?# box '((-2,-2),(2,2))'
+
+
+ ?-
+ Is horizontal?
+ point '(1,0)' ?- point '(0,0)'
+
+
+ ?-|
+ Is perpendicular?
+ lseg '((0,0),(0,1))' ?-| lseg '((0,0),(1,0))'
+
+
+ @-@
+ Length or circumference
+ @-@ path '((0,0),(1,0))'
+
+
+ ?|
+ Is vertical?
+ point '(0,1)' ?| point '(0,0)'
+
+
+ ?||
+ Is parallel?
+ lseg '((-1,0),(1,0))' ?|| lseg '((-1,2),(1,2))'
+
+
+ @
+ Contained or on
+ point '(1,1)' @ circle '((0,0),2)'
+
+
+ @@
+ Center of
+ @@ circle '((0,0),10)'
+
+
+ ~=
+ Same as
+ polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'
+
+
+
+
All of the operators for inet can be applied to
cidr values as well. The operators
- <<>, <<=>,
- >>>, >>=>
+ <<, <<=,
+ >>, >>=
test for subnet inclusion: they consider only the network parts
of the two addresses, ignoring any host part, and determine whether
one network part is identical to or a subnet of the other.
@@ -3722,7 +3803,7 @@ SELECT TIMESTAMP 'now';
- cidr> and inet> Functions
+ cidr and inet Functions
@@ -3796,15 +3877,15 @@ SELECT TIMESTAMP 'now';
All of the functions for inet can be applied to
- cidr values as well. The host>(),
- text>(), and abbrev>() functions are primarily
+ cidr values as well. The host(),
+ text(), and abbrev() functions are primarily
intended to offer alternative display formats. You can cast a text
field to inet using normal casting syntax: inet(expression) or
colname::inet.
- The function trunc>(macaddr>) returns a MAC
+ The function trunc(macaddr) returns a MAC
address with the last 3 bytes set to 0. This can be used to
associate the remaining prefix with a manufacturer. The directory
- contrib/mac> in the source distribution contains some
+ contrib/mac in the source distribution contains some
utilities to create and maintain such an association table.
- The macaddr> type also supports the standard relational
- operators (>>, <=>, etc.) for
+ The macaddr type also supports the standard relational
+ operators (>, <=, etc.) for
lexicographical ordering.
@@ -3861,32 +3942,32 @@ SELECT TIMESTAMP 'now';
- Sequence Functions>
+ Sequence Functions
- Function> Returns> Description>
+ FunctionReturnsDescriptionnextval(text)bigint
- Advance sequence and return new value>
+ Advance sequence and return new valuecurrval(text)bigint
- Return value most recently obtained with nextval>
+ Return value most recently obtained with nextvalsetval(text,bigint)bigint
- Set sequence's current value>
+ Set sequence's current value
- setval(text,bigint,boolean>)
+ setval(text,bigint,boolean)bigint
- Set sequence's current value and is_called> flag
+ Set sequence's current value and is_called flag
@@ -3894,10 +3975,10 @@ SELECT TIMESTAMP 'now';
This section describes PostgreSQL's functions
- for operating on sequence objects>.
+ for operating on sequence objects.
Sequence objects (also called sequence generators or
just sequences) are special single-row tables created with
- CREATE SEQUENCE>. A sequence object is usually used to
+ CREATE SEQUENCE. A sequence object is usually used to
generate unique identifiers for rows of a table. The sequence functions
provide simple, multiuser-safe methods for obtaining successive
sequence values from sequence objects.
@@ -3910,15 +3991,16 @@ SELECT TIMESTAMP 'now';
names, the sequence functions convert their argument to lower case
unless the string is double-quoted. Thus
-nextval('foo') operates on sequence >foo>
-nextval('FOO') operates on sequence >foo>
-nextval('"Foo"') operates on sequence >Foo>
+nextval('foo') operates on sequence >foo
+nextval('FOO') operates on sequence >foo
+nextval('"Foo"') operates on sequence >Foo
The sequence name can be schema-qualified if necessary:
-nextval('myschema.foo') operates on >myschema.foo>
-nextval('"myschema".foo') same as above>
-nextval('foo') searches search path for >foo>
+nextval('myschema.foo') operates on >myschema.foo
+nextval('"myschema".foo') same as above
+nextval('foo') searches search path for
+ >foo
Of course, the text argument can be the result of an expression,
not only a simple literal, which is occasionally useful.
@@ -3929,57 +4011,57 @@ nextval('foo') searches search path for >foo>
- nextval>
+ nextval
Advance the sequence object to its next value and return that
value. This is done atomically: even if multiple server processes
- execute nextval> concurrently, each will safely receive
+ execute nextval concurrently, each will safely receive
a distinct sequence value.
- currval>
+ currval
- Return the value most recently obtained by nextval>
+ Return the value most recently obtained by nextval
for this sequence in the current server process. (An error is
- reported if nextval> has never been called for this
+ reported if nextval has never been called for this
sequence in this process.) Notice that because this is returning
a process-local value, it gives a predictable answer even if other
- server processes are executing nextval> meanwhile.
+ server processes are executing nextval meanwhile.
- setval>
+ setval
Reset the sequence object's counter value. The two-parameter
- form sets the sequence's last_value> field to the specified
- value and sets its is_called> field to true>,
- meaning that the next nextval> will advance the sequence
+ form sets the sequence's last_value field to the specified
+ value and sets its is_called field to true,
+ meaning that the next nextval will advance the sequence
before returning a value. In the three-parameter form,
- is_called> may be set either true> or
- false>. If it's set to false>,
- the next nextval> will return exactly the specified
+ is_called may be set either true or
+ false. If it's set to false,
+ the next nextval will return exactly the specified
value, and sequence advancement commences with the following
- nextval>. For example,
+ nextval. For example,
-SELECT setval('foo', 42); Next nextval() will return 43>
-SELECT setval('foo', 42, true); Same as above>
-SELECT setval('foo', 42, false); Next nextval() will return 42>
+SELECT setval('foo', 42); Next nextval() will return 43
+SELECT setval('foo', 42, true); Same as above
+SELECT setval('foo', 42, false); Next nextval() will return 42
- The result returned by setval> is just the value of its
+ The result returned by setval is just the value of its
second argument.
@@ -3990,20 +4072,20 @@ SELECT setval('foo', 42, false); Next nextval() will return 4
To avoid blocking of concurrent transactions that obtain numbers from the
- same sequence, a nextval> operation is never rolled back;
+ same sequence, a nextval operation is never rolled back;
that is, once a value has been fetched it is considered used, even if the
- transaction that did the nextval> later aborts. This means
+ transaction that did the nextval later aborts. This means
that aborted transactions may leave unused holes in the
- sequence of assigned values. setval> operations are never
+ sequence of assigned values. setval operations are never
rolled back, either.
If a sequence object has been created with default parameters,
- nextval()> calls on it will return successive values
+ nextval() calls on it will return successive values
beginning with one. Other behaviors can be obtained by using
- special parameters in the CREATE SEQUENCE> command;
+ special parameters in the CREATE SEQUENCE command;
see its command reference page for more information.
@@ -4139,7 +4221,8 @@ END
COALESCE
-COALESCE(value, ...)
+COALESCE(value, ...)
@@ -4159,7 +4242,8 @@ SELECT COALESCE(description, short_description, '(none)') ...
-NULLIF(value1, value2)
+NULLIF(value1,
+ value2)
@@ -4190,39 +4274,39 @@ SELECT NULLIF(value, '(none)') ...
- Miscellaneous Functions>
+ Miscellaneous Functions
- Session Information Functions>
+ Session Information Functions
- Name> Return Type> Description>
+ NameReturn TypeDescription
- current_user>
- name>
+ current_user
+ nameuser name of current execution context
- session_user>
- name>
+ session_user
+ namesession user name
- user>
- name>
- equivalent to current_user>
+ user
+ name
+ equivalent to current_user
- current_schema()>
- name>
+ current_schema()
+ namename of current schema
- current_schemas()>
- name[]>
+ current_schemas()
+ name[]names of schemas in search path
@@ -4245,55 +4329,55 @@ SELECT NULLIF(value, '(none)') ...
- The session_user> is the user that initiated a
+ The session_user is the user that initiated a
database connection; it is fixed for the duration of that
- connection. The current_user> is the user identifier
+ connection. The current_user is the user identifier
that is applicable for permission checking. Normally, it is equal
to the session user, but it changes during the execution of
functions with the attribute SECURITY DEFINER.
- In Unix parlance, the session user is the real user> and
- the current user is the effective user>.
+ In Unix parlance, the session user is the real user and
+ the current user is the effective user.
- current_user>, session_user>, and
- user> have special syntactic status in SQL>:
+ current_user, session_user, and
+ user have special syntactic status in SQL:
they must be called without trailing parentheses.
- Deprecated>
+ Deprecated
- The function getpgusername()> is an obsolete equivalent
- of current_user>.
+ The function getpgusername() is an obsolete equivalent
+ of current_user.
- current_schema> returns the name of the schema that is
+ current_schema returns the name of the schema that is
at the front of the search path (or NULL if the search path is
empty). This is the schema that will be used for any tables or
other named objects that are created without specifying a target schema.
- current_schemas> returns an array of the names of all
+ current_schemas returns an array of the names of all
schemas presently in the search path. Note that these functions show
only schemas that are explicitly part of the path; when a system schema
is being searched implicitly, it is not listed.
- System Information Functions>
+ System Information Functions
- Name> Return Type> Description>
+ NameReturn TypeDescription
- version>
- text>
- PostgreSQL version information>
+ version
+ text
+ PostgreSQL version information
@@ -4304,15 +4388,15 @@ SELECT NULLIF(value, '(none)') ...
- version()> returns a string describing the PostgreSQL
+ version() returns a string describing the PostgreSQL
server's version.
- Access Privilege Inquiry Functions>
+ Access Privilege Inquiry Functions
- Name> Return Type> Description>
+ NameReturn TypeDescription
@@ -4321,15 +4405,15 @@ SELECT NULLIF(value, '(none)') ...
table,
access)
- boolean>
- does user have access to table>
+ boolean
+ does user have access to tablehas_table_privilege(table,
access)
- boolean>
- does current user have access to table>
+ boolean
+ does current user have access to table
@@ -4340,21 +4424,21 @@ SELECT NULLIF(value, '(none)') ...
- has_table_privilege> determines whether a user
+ has_table_privilege determines whether a user
can access a table in a particular way. The user can be
specified by name or by ID
- (pg_user>.usesysid>), or if the argument is
+ (pg_user.usesysid), or if the argument is
omitted
- current_user> is assumed. The table can be specified
+ current_user is assumed. The table can be specified
by name or by OID. (Thus, there are actually six variants of
- has_table_privilege>, which can be distinguished by
+ has_table_privilege, which can be distinguished by
the number and types of their arguments.) When specifying by name,
the name can be schema-qualified if necessary.
The desired access type
is specified by a text string, which must evaluate to one of the
- values SELECT>, INSERT>, UPDATE>,
- DELETE>, RULE>, REFERENCES>, or
- TRIGGER>. (Case of the string is not significant, however.)
+ values SELECT, INSERT, UPDATE,
+ DELETE, RULE, REFERENCES, or
+ TRIGGER. (Case of the string is not significant, however.)
An example is:
SELECT has_table_privilege('myschema.mytable', 'select');
@@ -4362,37 +4446,37 @@ SELECT has_table_privilege('myschema.mytable', 'select');
- Catalog Information Functions>
+ Catalog Information Functions
- Name> Return Type> Description>
+ NameReturn TypeDescription
- pg_get_viewdef>(viewname)
- text>
- Get CREATE VIEW command for view>
+ pg_get_viewdef(viewname)
+ text
+ Get CREATE VIEW command for view
- pg_get_viewdef>(viewOID)
- text>
- Get CREATE VIEW command for view>
+ pg_get_viewdef(viewOID)
+ text
+ Get CREATE VIEW command for view
- pg_get_ruledef>(ruleOID)
- text>
- Get CREATE RULE command for rule>
+ pg_get_ruledef(ruleOID)
+ text
+ Get CREATE RULE command for rule
- pg_get_indexdef>(indexOID)
- text>
- Get CREATE INDEX command for index>
+ pg_get_indexdef(indexOID)
+ text
+ Get CREATE INDEX command for index
- pg_get_userbyid>(userid)
- name>
- Get user name given ID>
+ pg_get_userbyid(userid)
+ name
+ Get user name given ID
@@ -4416,36 +4500,36 @@ SELECT has_table_privilege('myschema.mytable', 'select');
These functions extract information from the system catalogs.
- pg_get_viewdef()>, pg_get_ruledef()>, and
- pg_get_indexdef()> respectively reconstruct the creating
+ pg_get_viewdef(), pg_get_ruledef(), and
+ pg_get_indexdef() respectively reconstruct the creating
command for a view, rule, or index. (Note that this is a decompiled
reconstruction, not the verbatim text of the command.)
- pg_get_userbyid()> extracts a user's name given a
- usesysid> value.
+ pg_get_userbyid() extracts a user's name given a
+ usesysid value.
- Comment Information Functions>
+ Comment Information Functions
- Name> Return Type> Description>
+ NameReturn TypeDescription
- obj_description>(objectOID, tablename>)
- text>
- Get comment for a database object>
+ obj_description(objectOID, tablename)
+ text
+ Get comment for a database object
- obj_description>(objectOID)
- text>
- Get comment for a database object (deprecated>)
+ obj_description(objectOID)
+ text
+ Get comment for a database object (deprecated)
- col_description>(tableOID, columnnumber>)
- text>
- Get comment for a table column>
+ col_description(tableOID, columnnumber)
+ text
+ Get comment for a table column
@@ -4461,26 +4545,26 @@ SELECT has_table_privilege('myschema.mytable', 'select');
These functions extract comments previously stored with the
- COMMENT> command. NULL> is returned if
+ COMMENT command. NULL is returned if
no comment can be found matching the specified parameters.
- The two-parameter form of obj_description()> returns the
+ The two-parameter form of obj_description() returns the
comment for a database object specified by its OID and the name of the
containing system catalog. For example,
- obj_description(123456,'pg_class')>
+ obj_description(123456,'pg_class')
would retrieve the comment for a table with OID 123456.
- The one-parameter form of obj_description()> requires only
+ The one-parameter form of obj_description() requires only
the object OID. It is now deprecated since there is no guarantee that
OIDs are unique across different system catalogs; therefore, the wrong
comment could be returned.
- col_description()> returns the comment for a table column,
+ col_description() returns the comment for a table column,
which is specified by the OID of its table and its column number.
- obj_description()> cannot be used for table columns since
+ obj_description() cannot be used for table columns since
columns do not have OIDs of their own.
@@ -4501,7 +4585,7 @@ SELECT has_table_privilege('myschema.mytable', 'select');
Aggregate functions compute a single result
value from a set of input values. The special syntax
considerations for aggregate functions are explained in . Consult the PostgreSQL
+ linkend="syntax-aggregates">. Consult the PostgreSQL
Tutorial for additional introductory information.
@@ -4546,7 +4630,7 @@ SELECT has_table_privilege('myschema.mytable', 'select');
count(expression)
Counts the input values for which the value of expression is not NULL.
+ class="parameter">expression is not NULL.
The return value is of type bigint.
@@ -4570,7 +4654,8 @@ SELECT has_table_privilege('myschema.mytable', 'select');
- stddev(expression)
+ stddev(expression)the sample standard deviation of the input values
@@ -4602,7 +4687,8 @@ SELECT has_table_privilege('myschema.mytable', 'select');
- variance(expression)
+ variance(expression)the sample variance of the input values
@@ -4674,11 +4760,11 @@ EXISTS ( subquery )
- The argument of EXISTS> is an arbitrary SELECT statement,
- or subquery>. The
+ The argument of EXISTS is an arbitrary SELECT statement,
+ or subquery. The
subquery is evaluated to determine whether it returns any rows.
- If it returns at least one row, the result of EXISTS> is
- TRUE; if the subquery returns no rows, the result of EXISTS>
+ If it returns at least one row, the result of EXISTS is
+ TRUE; if the subquery returns no rows, the result of EXISTS
is FALSE.
@@ -4700,8 +4786,8 @@ EXISTS ( subquery )
and not on the contents of those rows, the output list of the
subquery is normally uninteresting. A common coding convention is
to write all EXISTS tests in the form
- EXISTS(SELECT 1 WHERE ...)>. There are exceptions to
- this rule however, such as subqueries that use INTERSECT>.
+ EXISTS(SELECT 1 WHERE ...). There are exceptions to
+ this rule however, such as subqueries that use INTERSECT.
@@ -4717,11 +4803,12 @@ SELECT col1 FROM tab1
IN (scalar form)
-expression IN (value, ...)
+expression IN
+ ble>value, ...)
- The right-hand side of this form of IN> is a parenthesized list
+ The right-hand side of this form of IN is a parenthesized list
of scalar expressions. The result is TRUE if the left-hand expression's
result is equal to any of the right-hand expressions. This is a shorthand
notation for
@@ -4736,15 +4823,15 @@ OR
Note that if the left-hand expression yields NULL, or if there are
no equal right-hand values and at least one right-hand expression yields
- NULL, the result of the IN> construct will be NULL, not FALSE.
+ NULL, the result of the IN construct will be NULL, not FALSE.
This is in accordance with SQL's normal rules for Boolean combinations
of NULL values.
- This form of IN> is not truly a subquery expression, but it
- seems best to document it in the same place as subquery IN>.
+ This form of IN is not truly a subquery expression, but it
+ seems best to document it in the same place as subquery IN.
@@ -4755,10 +4842,10 @@ OR
- The right-hand side of this form of IN> is a parenthesized
+ The right-hand side of this form of IN is a parenthesized
subquery, which must return exactly one column. The left-hand expression
is evaluated and compared to each row of the subquery result.
- The result of IN> is TRUE if any equal subquery row is found.
+ The result of IN is TRUE if any equal subquery row is found.
The result is FALSE if no equal row is found (including the special
case where the subquery returns no rows).
@@ -4766,26 +4853,28 @@ OR
Note that if the left-hand expression yields NULL, or if there are
no equal right-hand values and at least one right-hand row yields
- NULL, the result of the IN> construct will be NULL, not FALSE.
+ NULL, the result of the IN construct will be NULL, not FALSE.
This is in accordance with SQL's normal rules for Boolean combinations
of NULL values.
- As with EXISTS>, it's unwise to assume that the subquery will
+ As with EXISTS, it's unwise to assume that the subquery will
be evaluated completely.
-(expression, expression, ...) IN (subquery)
+(expression,
+ble>expresnal>,nal>)
+ IN (subquery)
- The right-hand side of this form of IN> is a parenthesized
+ The right-hand side of this form of IN is a parenthesized
subquery, which must return exactly as many columns as there are
expressions in the left-hand list. The left-hand expressions are
evaluated and compared row-wise to each row of the subquery result.
- The result of IN> is TRUE if any equal subquery row is found.
+ The result of IN is TRUE if any equal subquery row is found.
The result is FALSE if no equal row is found (including the special
case where the subquery returns no rows).
@@ -4797,17 +4886,18 @@ OR
are unequal if any corresponding members are non-null and unequal;
otherwise the result of that row comparison is unknown (NULL).
If all the row results are either unequal or NULL, with at least one NULL,
- then the result of IN> is NULL.
+ then the result of IN is NULL.
NOT IN (scalar form)
-expression NOT IN (value, ...)
+expression NOT IN
+ ble>value, ...)
- The right-hand side of this form of NOT IN> is a parenthesized list
+ The right-hand side of this form of NOT IN is a parenthesized list
of scalar expressions. The result is TRUE if the left-hand expression's
result is unequal to all of the right-hand expressions. This is a shorthand
notation for
@@ -4822,7 +4912,7 @@ AND
Note that if the left-hand expression yields NULL, or if there are
no equal right-hand values and at least one right-hand expression yields
- NULL, the result of the NOT IN> construct will be NULL, not TRUE
+ NULL, the result of the NOT IN construct will be NULL, not TRUE
as one might naively expect.
This is in accordance with SQL's normal rules for Boolean combinations
of NULL values.
@@ -4830,9 +4920,9 @@ AND
- x NOT IN y> is equivalent to NOT (x IN y)> in all
+ x NOT IN y is equivalent to NOT (x IN y) in all
cases. However, NULLs are much more likely to trip up the novice when
- working with NOT IN> than when working with IN>.
+ working with NOT IN than when working with IN.
It's best to express your condition positively if possible.
@@ -4844,10 +4934,10 @@ AND
- The right-hand side of this form of NOT IN> is a parenthesized
+ The right-hand side of this form of NOT IN is a parenthesized
subquery, which must return exactly one column. The left-hand expression
is evaluated and compared to each row of the subquery result.
- The result of NOT IN> is TRUE if only unequal subquery rows
+ The result of NOT IN is TRUE if only unequal subquery rows
are found (including the special case where the subquery returns no rows).
The result is FALSE if any equal row is found.
@@ -4855,26 +4945,28 @@ AND
Note that if the left-hand expression yields NULL, or if there are
no equal right-hand values and at least one right-hand row yields
- NULL, the result of the NOT IN> construct will be NULL, not TRUE.
+ NULL, the result of the NOT IN construct will be NULL, not TRUE.
This is in accordance with SQL's normal rules for Boolean combinations
of NULL values.
- As with EXISTS>, it's unwise to assume that the subquery will
+ As with EXISTS, it's unwise to assume that the subquery will
be evaluated completely.
-(expression, expression, ...) NOT IN (subquery)
+(expression,
+ble>expresnal>,nal>)
+ NOT IN (subquery)
- The right-hand side of this form of NOT IN> is a parenthesized
+ The right-hand side of this form of NOT IN is a parenthesized
subquery, which must return exactly as many columns as there are
expressions in the left-hand list. The left-hand expressions are
evaluated and compared row-wise to each row of the subquery result.
- The result of NOT IN> is TRUE if only unequal subquery rows
+ The result of NOT IN is TRUE if only unequal subquery rows
are found (including the special case where the subquery returns no rows).
The result is FALSE if any equal row is found.
@@ -4886,59 +4978,63 @@ AND
are unequal if any corresponding members are non-null and unequal;
otherwise the result of that row comparison is unknown (NULL).
If all the row results are either unequal or NULL, with at least one NULL,
- then the result of NOT IN> is NULL.
+ then the result of NOT IN is NULL.
ANY
-expressionoperator ANY (subquery)
-expressionoperator SOME (subquery)
+expression
+ble>operble> ANY (subquery)
+expression
+ble>operble> SOME (subquery)
- The right-hand side of this form of ANY> is a parenthesized
+ The right-hand side of this form of ANY is a parenthesized
subquery, which must return exactly one column. The left-hand expression
is evaluated and compared to each row of the subquery result using the
given operator, which must yield a Boolean
result.
- The result of ANY> is TRUE if any true result is obtained.
+ The result of ANY is TRUE if any true result is obtained.
The result is FALSE if no true result is found (including the special
case where the subquery returns no rows).
- SOME> is a synonym for ANY>.
- IN> is equivalent to = ANY>.
+ SOME is a synonym for ANY.
+ IN is equivalent to = ANY.
Note that if there are no successes and at least one right-hand row yields
- NULL for the operator's result, the result of the ANY> construct
+ NULL for the operator's result, the result of the ANY construct
will be NULL, not FALSE.
This is in accordance with SQL's normal rules for Boolean combinations
of NULL values.
- As with EXISTS>, it's unwise to assume that the subquery will
+ As with EXISTS, it's unwise to assume that the subquery will
be evaluated completely.
-(expression, expression, ...) operator ANY (subquery)
-(expression, expression, ...) operator SOME (subquery)
+(expression,
+ble>expresnal>,optionaaceable>aceable> ANY (subquery)
+(expression,
+ble>expresnal>,optionaaceable>aceable> SOME (subquery)
- The right-hand side of this form of ANY> is a parenthesized
+ The right-hand side of this form of ANY is a parenthesized
subquery, which must return exactly as many columns as there are
expressions in the left-hand list. The left-hand expressions are
evaluated and compared row-wise to each row of the subquery result,
using the given operator. Presently,
- only => and <>> operators are allowed
- in row-wise ANY> queries.
- The result of ANY> is TRUE if any equal or unequal row is
+ only = and <> operators are allowed
+ in row-wise ANY queries.
+ The result of ANY is TRUE if any equal or unequal row is
found, respectively.
The result is FALSE if no such row is found (including the special
case where the subquery returns no rows).
@@ -4950,57 +5046,58 @@ AND
equal if all their corresponding members are non-null and equal; the rows
are unequal if any corresponding members are non-null and unequal;
otherwise the result of that row comparison is unknown (NULL).
- If there is at least one NULL row result, then the result of ANY>
+ If there is at least one NULL row result, then the result of ANY
cannot be FALSE; it will be TRUE or NULL.
ALL
-expressionoperator ALL (subquery)
+expression
+ble>operble> ALL (subquery)
- The right-hand side of this form of ALL> is a parenthesized
+ The right-hand side of this form of ALL is a parenthesized
subquery, which must return exactly one column. The left-hand expression
is evaluated and compared to each row of the subquery result using the
given operator, which must yield a Boolean
result.
- The result of ALL> is TRUE if all rows yield TRUE
+ The result of ALL is TRUE if all rows yield TRUE
(including the special case where the subquery returns no rows).
The result is FALSE if any false result is found.
- NOT IN> is equivalent to <> ALL>.
+ NOT IN is equivalent to <> ALL.
Note that if there are no failures but at least one right-hand row yields
- NULL for the operator's result, the result of the ALL> construct
+ NULL for the operator's result, the result of the ALL construct
will be NULL, not TRUE.
This is in accordance with SQL's normal rules for Boolean combinations
of NULL values.
- As with EXISTS>, it's unwise to assume that the subquery will
+ As with EXISTS, it's unwise to assume that the subquery will
be evaluated completely.
-
+
(expression, expression, ...) operator ALL (subquery)
-
+
- The right-hand side of this form of ALL> is a parenthesized
+ The right-hand side of this form of ALL is a parenthesized
subquery, which must return exactly as many columns as there are
expressions in the left-hand list. The left-hand expressions are
evaluated and compared row-wise to each row of the subquery result,
using the given operator. Presently,
- only => and <>> operators are allowed
- in row-wise ALL> queries.
- The result of ALL> is TRUE if all subquery rows are equal
+ only = and <> operators are allowed
+ in row-wise ALL queries.
+ The result of ALL is TRUE if all subquery rows are equal
or unequal, respectively (including the special
case where the subquery returns no rows).
The result is FALSE if any row is found to be unequal or equal,
@@ -5013,16 +5110,16 @@ AND
equal if all their corresponding members are non-null and equal; the rows
are unequal if any corresponding members are non-null and unequal;
otherwise the result of that row comparison is unknown (NULL).
- If there is at least one NULL row result, then the result of ALL>
+ If there is at least one NULL row result, then the result of ALL
cannot be TRUE; it will be FALSE or NULL.
Row-wise comparison
-
+
(expression, expression, ...) operator (subquery)
-(expression, expression, ...) operator (expression, expression, ...)
-
+(expression, expression, ...) operator (expressionexpression, ...)
+
The left-hand side is a list of scalar expressions. The right-hand side
@@ -5032,7 +5129,7 @@ AND
return more than one row. (If it returns zero rows, the result is taken to
be NULL.) The left-hand side is evaluated and compared row-wise to the
single subquery result row, or to the right-hand expression list.
- Presently, only => and <>> operators are allowed
+ Presently, only = and <> operators are allowed
in row-wise comparisons.
The result is TRUE if the two rows are equal or unequal, respectively.
diff --git a/doc/src/sgml/release.sgml b/doc/src/sgml/release.sgml
index 0bdb095804..9cd74fae20 100644
--- a/doc/src/sgml/release.sgml
+++ b/doc/src/sgml/release.sgml
@@ -1,5 +1,5 @@
@@ -44,6 +44,9 @@ Access privileges on procedural languages
CREATE DATABASE has OWNER option so superuser can create DB for someone else
Kerberos 5 support now works with Heimdal
Database and user-specific session defaults for run-time configuration variables (ALTER DATABASE ... SET and ALTER USER ... SET)
+String function OVERLAY() implemented per SQL99
+Regular expression operator SIMILAR TO implemented per SQL99
+Regular expression function SUBSTRING() implemented per SQL99
]]>