diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index cea3dcd2c0..96ea57eedd 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -16818,18 +16818,6 @@ $ ? (@ like_regex "^\\d+$")
sequence
-
- nextval
-
-
- currval
-
-
- lastval
-
-
- setval
-
This section describes functions for operating on sequence
@@ -16845,43 +16833,158 @@ $ ? (@ like_regex "^\\d+$")
Sequence Functions
-
+
- Function Return Type Description
+
+
+ Function
+
+
+ Description
+
+
- currval(regclass)
- bigint
- Return value most recently obtained with
- nextval for specified sequence
+
+
+ nextval
+
+ nextval ( regclass )
+ bigint
+
+
+ Advances the sequence object to its next value and returns that value.
+ This is done atomically: even if multiple sessions
+ execute nextval concurrently, each will safely
+ receive a distinct sequence value.
+ If the sequence object has been created with default parameters,
+ successive nextval calls will return successive
+ values beginning with 1. Other behaviors can be obtained by using
+ appropriate parameters in the
+ command.
+
+
+ This function requires USAGE
+ or UPDATE privilege on the sequence.
+
+
- lastval()
- bigint
- Return value most recently obtained with
- nextval for any sequence
+
+
+ setval
+
+ setval ( regclass, bigint , boolean )
+ bigint
+
+
+ Sets the sequence object's current value, and optionally
+ its is_called flag. 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 before
+ returning a value. The value that will be reported
+ by currval is also set to the specified value.
+ In the three-parameter form, is_called can be set
+ to either true
+ or false. true has the same
+ effect as the two-parameter form. If it is set
+ to false, the next nextval
+ will return exactly the specified value, and sequence advancement
+ commences with the following nextval.
+ Furthermore, the value reported by currval is not
+ changed in this case. For example,
+
+SELECT setval('myseq', 42); Next nextval will return 43
+SELECT setval('myseq', 42, true); Same as above
+SELECT setval('myseq', 42, false); Next nextval will return 42
+
+ The result returned by setval is just the value of its
+ second argument.
+
+
+ This function requires UPDATE privilege on the
+ sequence.
+
+
- nextval(regclass)
- bigint
- Advance sequence and return new value
+
+
+ currval
+
+ currval ( regclass )
+ bigint
+
+
+ Returns the value most recently obtained
+ by nextval for this sequence in the current
+ session. (An error is reported if nextval has
+ never been called for this sequence in this session.) Because this is
+ returning a session-local value, it gives a predictable answer whether
+ or not other sessions have executed nextval since
+ the current session did.
+
+
+ This function requires USAGE
+ or SELECT privilege on the sequence.
+
+
- setval(regclass, bigint)
- bigint
- Set sequence's current value
-
-
- setval(regclass, bigint, boolean)
- bigint
- Set sequence's current value and is_called flag
+
+
+ lastval
+
+ lastval ()
+ bigint
+
+
+ Returns the value most recently returned by
+ nextval in the current session. This function is
+ identical to currval, except that instead
+ of taking the sequence name as an argument it refers to whichever
+ sequence nextval was most recently applied to
+ in the current session. It is an error to call
+ lastval if nextval
+ has not yet been called in the current session.
+
+
+ This function requires USAGE
+ or SELECT privilege on the last used sequence.
+
+
+
+ To avoid blocking concurrent transactions that obtain numbers from
+ the same sequence, a nextval operation is never
+ rolled back; that is, once a value has been fetched it is considered
+ used and will not be returned again. This is true even if the
+ surrounding transaction later aborts, or if the calling query ends
+ up not using the value. For example an INSERT with
+ an ON CONFLICT clause will compute the to-be-inserted
+ tuple, including doing any required nextval
+ calls, before detecting any conflict that would cause it to follow
+ the ON CONFLICT rule instead. Such cases will leave
+ unused holes
in the sequence of assigned values.
+ Thus, PostgreSQL sequence
+ objects cannot be used to obtain gapless
+ sequences.
+
+
+
+ Likewise, any sequence state changes made by setval
+ are not undone if the transaction rolls back.
+
+
+
The sequence to be operated on by a sequence function is specified by
a regclass argument, which is simply the OID of the sequence in the
@@ -16943,139 +17046,6 @@ nextval('foo'::text) foo is looked up at
-
- The available sequence functions are:
-
-
-
- nextval
-
-
- Advance the sequence object to its next value and return that
- value. This is done atomically: even if multiple sessions
- execute nextval concurrently, each will safely receive
- a distinct sequence value.
-
-
-
- If a sequence object has been created with default parameters,
- successive nextval calls will return successive
- values beginning with 1. Other behaviors can be obtained by using
- special parameters in the command;
- see its command reference page for more information.
-
-
-
-
- To avoid blocking concurrent transactions that obtain numbers from
- the same sequence, a nextval operation is never
- rolled back; that is, once a value has been fetched it is considered
- used and will not be returned again. This is true even if the
- surrounding transaction later aborts, or if the calling query ends
- up not using the value. For example an INSERT with
- an ON CONFLICT clause will compute the to-be-inserted
- tuple, including doing any required nextval
- calls, before detecting any conflict that would cause it to follow
- the ON CONFLICT rule instead. Such cases will leave
- unused holes
in the sequence of assigned values.
- Thus, PostgreSQL sequence objects cannot
- be used to obtain gapless
sequences.
-
-
-
-
- This function requires USAGE
- or UPDATE privilege on the sequence.
-
-
-
-
-
- currval
-
-
- Return the value most recently obtained by nextval
- for this sequence in the current session. (An error is
- reported if nextval has never been called for this
- sequence in this session.) Because this is returning
- a session-local value, it gives a predictable answer whether or not
- other sessions have executed nextval since the
- current session did.
-
-
-
- This function requires USAGE
- or SELECT privilege on the sequence.
-
-
-
-
-
- lastval
-
-
- Return the value most recently returned by
- nextval in the current session. This function is
- identical to currval, except that instead
- of taking the sequence name as an argument it refers to whichever
- sequence nextval was most recently applied to
- in the current session. It is an error to call
- lastval if nextval
- has not yet been called in the current session.
-
-
-
- This function requires USAGE
- or SELECT privilege on the last used sequence.
-
-
-
-
-
- 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 before
- returning a value. The value reported by currval is
- also set to the specified value. In the three-parameter form,
- is_called can be set to either true
- or false. true has the same effect as
- the two-parameter form. If it is set to false, the
- next nextval will return exactly the specified
- value, and sequence advancement commences with the following
- nextval. Furthermore, the value reported by
- currval is not changed in this case. 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
-
-
- The result returned by setval is just the value of its
- second argument.
-
-
-
- Because sequences are non-transactional, changes made by
- setval are not undone if the transaction rolls
- back.
-
-
-
-
- This function requires UPDATE privilege on the
- sequence.
-
-
-
-
-
-
@@ -17346,119 +17316,11 @@ SELECT NULLIF(value, '(none)') ...
Array Functions and Operators
- shows the operators
+ shows the specialized operators
available for array types.
-
-
-
- Array Operators
-
-
-
- Operator
- Description
- Example
- Result
-
-
-
-
- =
- equal
- ARRAY[1.1,2.1,3.1]::int[] = ARRAY[1,2,3]
- t
-
-
-
- <>
- not equal
- ARRAY[1,2,3] <> ARRAY[1,2,4]
- t
-
-
-
- <
- less than
- ARRAY[1,2,3] < ARRAY[1,2,4]
- t
-
-
-
- >
- greater than
- ARRAY[1,4,3] > ARRAY[1,2,4]
- t
-
-
-
- <=
- less than or equal
- ARRAY[1,2,3] <= ARRAY[1,2,3]
- t
-
-
-
- >=
- greater than or equal
- ARRAY[1,4,3] >= ARRAY[1,4,3]
- t
-
-
-
- @>
- contains
- ARRAY[1,4,3] @> ARRAY[3,1,3]
- t
-
-
-
- <@
- is contained by
- ARRAY[2,2,7] <@ ARRAY[1,7,4,2,6]
- t
-
-
-
- &&
- overlap (have elements in common)
- ARRAY[1,4,3] && ARRAY[2,1]
- t
-
-
-
- ||
- array-to-array concatenation
- ARRAY[1,2,3] || ARRAY[4,5,6]
- {1,2,3,4,5,6}
-
-
-
- ||
- array-to-array concatenation
- ARRAY[1,2,3] || ARRAY[[4,5,6],[7,8,9]]
- {{1,2,3},{4,5,6},{7,8,9}}
-
-
-
- ||
- element-to-array concatenation
- 3 || ARRAY[4,5,6]
- {3,4,5,6}
-
-
-
- ||
- array-to-element concatenation
- ARRAY[4,5,6] || 7
- {4,5,6,7}
-
-
-
-
-
-
- The array ordering operators (<,
- >=, etc) compare the array contents
+ In addition to those, the usual comparison operators shown in are available for
+ arrays. The comparison operators compare the array contents
element-by-element, using the default B-tree comparison function for
the element data type, and sort based on the first difference.
In multidimensional arrays the elements are visited in row-major order
@@ -17471,14 +17333,123 @@ SELECT NULLIF(value, '(none)') ...
number of dimensions or subscript ranges were different.)
-
- The array containment operators (<@
- and @>) consider one array to be contained in
- another one if each of its elements appears in the other one.
- Duplicates are not treated specially, thus ARRAY[1]
- and ARRAY[1,1] are each considered to contain the
- other.
-
+
+ Array Operators
+
+
+
+
+ Operator
+
+
+ Description
+
+
+ Example(s)
+
+
+
+
+
+
+
+ anyarray @> anyarray
+ boolean
+
+
+ Does the first array contain the second, that is, does each element
+ appearing in the second array equal some element of the first array?
+ (Duplicates are not treated specially,
+ thus ARRAY[1] and ARRAY[1,1] are
+ each considered to contain the other.)
+
+
+ ARRAY[1,4,3] @> ARRAY[3,1,3]
+ t
+
+
+
+
+
+ anyarray <@ anyarray
+ boolean
+
+
+ Is the first array contained by the second?
+
+
+ ARRAY[2,2,7] <@ ARRAY[1,7,4,2,6]
+ t
+
+
+
+
+
+ anyarray && anyarray
+ boolean
+
+
+ Do the arrays overlap, that is, have any elements in common?
+
+
+ ARRAY[1,4,3] && ARRAY[2,1]
+ t
+
+
+
+
+
+ anyarray || anyarray
+ anyarray
+
+
+ Concatenates the two arrays. Concatenating a null or empty array is a
+ no-op; otherwise the arrays must have the same number of dimensions
+ (as illustrated by the first example) or differ in number of
+ dimensions by one (as illustrated by the second).
+
+
+ ARRAY[1,2,3] || ARRAY[4,5,6,7]
+ {1,2,3,4,5,6,7}
+
+
+ ARRAY[1,2,3] || ARRAY[[4,5,6],[7,8,9]]
+ {{1,2,3},{4,5,6},{7,8,9}}
+
+
+
+
+
+ anyelement || anyarray
+ anyarray
+
+
+ Concatenates an element onto the front of an array (which must be
+ empty or one-dimensional).
+
+
+ 3 || ARRAY[4,5,6]
+ {3,4,5,6}
+
+
+
+
+
+ anyarray || anyelement
+ anyarray
+
+
+ Concatenates an element onto the end of an array (which must be
+ empty or one-dimensional).
+
+
+ ARRAY[4,5,6] || 7
+ {4,5,6,7}
+
+
+
+
+
See for more details about array operator
@@ -17492,329 +17463,400 @@ SELECT NULLIF(value, '(none)') ...
for more information and examples of the use of these functions.
-
- array_append
-
-
- array_cat
-
-
- array_ndims
-
-
- array_dims
-
-
- array_fill
-
-
- array_length
-
-
- array_lower
-
-
- array_position
-
-
- array_positions
-
-
- array_prepend
-
-
- array_remove
-
-
- array_replace
-
-
- array_to_string
-
-
- array_upper
-
-
- cardinality
-
-
- string_to_array
-
-
- unnest
-
+
+ Array Functions
+
+
+
+
+ Function
+
+
+ Description
+
+
+ Example(s)
+
+
+
-
- Array Functions
-
-
-
- Function
- Return Type
- Description
- Example
- Result
-
-
-
-
-
-
- array_append(anyarray, anyelement)
-
-
- anyarray
- append an element to the end of an array
- array_append(ARRAY[1,2], 3)
- {1,2,3}
-
-
-
-
- array_cat(anyarray, anyarray)
-
-
- anyarray
- concatenate two arrays
- array_cat(ARRAY[1,2,3], ARRAY[4,5])
- {1,2,3,4,5}
-
-
-
-
- array_ndims(anyarray)
-
-
- int
- returns the number of dimensions of the array
- array_ndims(ARRAY[[1,2,3], [4,5,6]])
- 2
-
-
-
-
- array_dims(anyarray)
-
-
- text
- returns a text representation of array's dimensions
- array_dims(ARRAY[[1,2,3], [4,5,6]])
- [1:2][1:3]
-
-
-
-
- array_fill(anyelement, int[]
- , int[])
-
-
- anyarray
- returns an array initialized with supplied value and
- dimensions, optionally with lower bounds other than 1
- array_fill(7, ARRAY[3], ARRAY[2])
- [2:4]={7,7,7}
-
-
-
-
- array_length(anyarray, int)
-
-
- int
- returns the length of the requested array dimension
- array_length(array[1,2,3], 1)
- 3
-
-
-
-
- array_lower(anyarray, int)
-
-
- int
- returns lower bound of the requested array dimension
- array_lower('[0:2]={1,2,3}'::int[], 1)
- 0
-
-
-
-
- array_position(anyarray, anyelement , int)
-
-
- int
- returns the subscript of the first occurrence of the second
- argument in the array, starting at the element indicated by the third
- argument or at the first element (array must be one-dimensional)
- array_position(ARRAY['sun','mon','tue','wed','thu','fri','sat'], 'mon')
- 2
-
-
-
-
- array_positions(anyarray, anyelement)
-
-
- int[]
- returns an array of subscripts of all occurrences of the second
- argument in the array given as first argument (array must be
- one-dimensional)
- array_positions(ARRAY['A','A','B','A'], 'A')
- {1,2,4}
-
-
-
-
- array_prepend(anyelement, anyarray)
-
-
- anyarray
- append an element to the beginning of an array
- array_prepend(1, ARRAY[2,3])
- {1,2,3}
-
-
-
-
- array_remove(anyarray, anyelement)
-
-
- anyarray
- remove all elements equal to the given value from the array
- (array must be one-dimensional)
- array_remove(ARRAY[1,2,3,2], 2)
- {1,3}
-
-
-
-
- array_replace(anyarray, anyelement, anyelement)
-
-
- anyarray
- replace each array element equal to the given value with a new value
- array_replace(ARRAY[1,2,5,4], 5, 3)
- {1,2,3,4}
-
-
-
-
- array_to_string(anyarray, text , text)
-
-
- text
- concatenates array elements using supplied delimiter and
- optional null string
- array_to_string(ARRAY[1, 2, 3, NULL, 5], ',', '*')
- 1,2,3,*,5
-
-
-
-
- array_upper(anyarray, int)
-
-
- int
- returns upper bound of the requested array dimension
- array_upper(ARRAY[1,8,3,7], 1)
- 4
-
-
-
-
- cardinality(anyarray)
-
-
- int
- returns the total number of elements in the array, or 0 if the array is empty
- cardinality(ARRAY[[1,2],[3,4]])
- 4
-
-
-
-
- string_to_array(text, text , text)
-
-
- text[]
- splits string into array elements using supplied delimiter and
- optional null string
- string_to_array('xx~^~yy~^~zz', '~^~', 'yy')
- {xx,NULL,zz}
-
-
-
-
- unnest(anyarray)
-
-
- setof anyelement
- expand an array to a set of rows
- unnest(ARRAY[1,2])
- 1
-2(2 rows)
-
-
-
-
- unnest(anyarray, anyarray [, ...])
-
-
- setof anyelement, anyelement [, ...]
- expand multiple arrays (possibly of different types) to a set
- of rows. This is only allowed in the FROM clause; see
-
- unnest(ARRAY[1,2],ARRAY['foo','bar','baz'])
- 1 foo
-2 bar
-NULL baz(3 rows)
-
-
-
-
+
+
+
+
+ array_append
+
+ array_append ( anyarray, anyelement )
+ anyarray
+
+
+ Appends an element to the end of an array (same as
+ the anyarray || anyelement
+ operator).
+
+
+ array_append(ARRAY[1,2], 3)
+ {1,2,3}
+
+
-
- In array_position and array_positions,
- each array element is compared to the searched value using
- IS NOT DISTINCT FROM semantics.
-
+
+
+
+ array_cat
+
+ array_cat ( anyarray, anyarray )
+ anyarray
+
+
+ Concatenates two arrays (same as
+ the anyarray || anyarray
+ operator).
+
+
+ array_cat(ARRAY[1,2,3], ARRAY[4,5])
+ {1,2,3,4,5}
+
+
-
- In array_position, NULL is returned
- if the value is not found.
-
+
+
+
+ array_dims
+
+ array_dims ( anyarray )
+ text
+
+
+ Returns a text representation of the array's dimensions.
+
+
+ array_dims(ARRAY[[1,2,3], [4,5,6]])
+ [1:2][1:3]
+
+
-
- In array_positions, NULL is returned
- only if the array is NULL; if the value is not found in
- the array, an empty array is returned instead.
-
+
+
+
+ array_fill
+
+ array_fill ( anyelement, integer[]
+ , integer[] )
+ anyarray
+
+
+ Returns an array filled with copies of the given value, having
+ dimensions of the lengths specified by the second argument.
+ The optional third argument supplies lower-bound values for each
+ dimension (which default to all 1).
+
+
+ array_fill(11, ARRAY[2,3])
+ {{11,11,11},{11,11,11}}
+
+
+ array_fill(7, ARRAY[3], ARRAY[2])
+ [2:4]={7,7,7}
+
+
-
- In string_to_array, if the delimiter parameter is
- NULL, each character in the input string will become a separate element in
- the resulting array. If the delimiter is an empty string, then the entire
- input string is returned as a one-element array. Otherwise the input
- string is split at each occurrence of the delimiter string.
-
+
+
+
+ array_length
+
+ array_length ( anyarray, integer )
+ integer
+
+
+ Returns the length of the requested array dimension.
+
+
+ array_length(array[1,2,3], 1)
+ 3
+
+
-
- In string_to_array, if the null-string parameter
- is omitted or NULL, none of the substrings of the input will be replaced
- by NULL.
- In array_to_string, if the null-string parameter
- is omitted or NULL, any null elements in the array are simply skipped
- and not represented in the output string.
-
+
+
+
+ array_lower
+
+ array_lower ( anyarray, integer )
+ integer
+
+
+ Returns the lower bound of the requested array dimension.
+
+
+ array_lower('[0:2]={1,2,3}'::integer[], 1)
+ 0
+
+
+
+
+
+
+ array_ndims
+
+ array_ndims ( anyarray )
+ integer
+
+
+ Returns the number of dimensions of the array.
+
+
+ array_ndims(ARRAY[[1,2,3], [4,5,6]])
+ 2
+
+
+
+
+
+
+ array_position
+
+ array_position ( anyarray, anyelement , integer )
+ integer
+
+
+ Returns the subscript of the first occurrence of the second argument
+ in the array, or NULL if it's not present.
+ If the third argument is given, the search begins at that subscript.
+ The array must be one-dimensional.
+ Comparisons are done using IS NOT DISTINCT FROM
+ semantics, so it is possible to search for NULL.
+
+
+ array_position(ARRAY['sun', 'mon', 'tue', 'wed', 'thu', 'fri', 'sat'], 'mon')
+ 2
+
+
+
+
+
+
+ array_positions
+
+ array_positions ( anyarray, anyelement )
+ integer[]
+
+
+ Returns an array of the subscripts of all occurrences of the second
+ argument in the array given as first argument.
+ The array must be one-dimensional.
+ Comparisons are done using IS NOT DISTINCT FROM
+ semantics, so it is possible to search for NULL.
+ NULL is returned only if the array
+ is NULL; if the value is not found in the array, an
+ empty array is returned.
+
+
+ array_positions(ARRAY['A','A','B','A'], 'A')
+ {1,2,4}
+
+
+
+
+
+
+ array_prepend
+
+ array_prepend ( anyelement, anyarray )
+ anyarray
+
+
+ Prepends an element to the beginning of an array (same as
+ the anyelement || anyarray
+ operator).
+
+
+ array_prepend(1, ARRAY[2,3])
+ {1,2,3}
+
+
+
+
+
+
+ array_remove
+
+ array_remove ( anyarray, anyelement )
+ anyarray
+
+
+ Removes all elements equal to the given value from the array.
+ The array must be one-dimensional.
+ Comparisons are done using IS NOT DISTINCT FROM
+ semantics, so it is possible to remove NULLs.
+
+
+ array_remove(ARRAY[1,2,3,2], 2)
+ {1,3}
+
+
+
+
+
+
+ array_replace
+
+ array_replace ( anyarray, anyelement, anyelement )
+ anyarray
+
+
+ Replaces each array element equal to the second argument with the
+ third argument.
+
+
+ array_replace(ARRAY[1,2,5,4], 5, 3)
+ {1,2,3,4}
+
+
+
+
+
+
+ array_to_string
+
+ array_to_string ( array anyarray, delimiter text , null_string text )
+ text
+
+
+ Converts each array element to its text representation, and
+ concatenates those separated by
+ the delimiter string.
+ If null_string is given and is
+ not NULL, then NULL array
+ entries are represented by that string; otherwise, they are omitted.
+
+
+ array_to_string(ARRAY[1, 2, 3, NULL, 5], ',', '*')
+ 1,2,3,*,5
+
+
+
+
+
+
+ array_upper
+
+ array_upper ( anyarray, integer )
+ integer
+
+
+ Returns the upper bound of the requested array dimension.
+
+
+ array_upper(ARRAY[1,8,3,7], 1)
+ 4
+
+
+
+
+
+
+ cardinality
+
+ cardinality ( anyarray )
+ integer
+
+
+ Returns the total number of elements in the array, or 0 if the array
+ is empty.
+
+
+ cardinality(ARRAY[[1,2],[3,4]])
+ 4
+
+
+
+
+
+
+ string_to_array
+
+ string_to_array ( string text, delimiter text , null_string text )
+ text[]
+
+
+ Splits the string at occurrences
+ of delimiter and forms the remaining data
+ into a text array.
+ If delimiter is NULL,
+ each character in the string will become a
+ separate element in the array.
+ If delimiter is an empty string, then
+ the string is treated as a single field.
+ If null_string is supplied and is
+ not NULL, fields matching that string are converted
+ to NULL entries.
+
+
+ string_to_array('xx~~yy~~zz', '~~', 'yy')
+ {xx,NULL,zz}
+
+
+
+
+
+
+ unnest
+
+ unnest ( anyarray )
+ setof anyelement
+
+
+ Expands an array to a set of rows.
+
+
+ unnest(ARRAY[1,2])
+
+
+ 1
+ 2
+
+ (2 rows in result)
+
+
+
+
+
+ unnest ( anyarray, anyarray , ... )
+ setof anyelement, anyelement [, ... ]
+
+
+ Expands multiple arrays (possibly of different data types) to a set of
+ rows. If the arrays are not all the same length then the shorter ones
+ are padded with NULLs. This is only allowed in a
+ query's FROM clause; see .
+
+
+ select * from unnest(ARRAY[1,2], ARRAY['foo','bar','baz']) as x(a,b)
+
+
+ a | b
+---+-----
+ 1 | foo
+ 2 | bar
+ | baz
+
+
+
+
+
+
There are two differences in the behavior of string_to_array
from pre-9.1 versions of PostgreSQL.
- First, it will return an empty (zero-element) array rather than NULL when
- the input string is of zero length. Second, if the delimiter string is
- NULL, the function splits the input into individual characters, rather
- than returning NULL as before.
+ First, it will return an empty (zero-element) array rather
+ than NULL when the input string is of zero length.
+ Second, if the delimiter string is NULL, the function
+ splits the input into individual characters, rather than
+ returning NULL as before.
@@ -17832,167 +17874,222 @@ NULL baz(3 rows)
- shows the operators
+ shows the specialized operators
available for range types.
+ In addition to those, the usual comparison operators shown in
+ are available for range
+ types. The comparison operators order first by the range lower bounds, and
+ only if those are equal do they compare the upper bounds. This does not
+ usually result in a useful overall ordering, but the operators are provided
+ to allow unique indexes to be constructed on ranges.
-
- Range Operators
-
-
-
- Operator
- Description
- Example
- Result
-
-
-
-
- =
- equal
- int4range(1,5) = '[1,4]'::int4range
- t
-
+
+ Range Operators
+
+
+
+
+ Operator
+
+
+ Description
+
+
+ Example(s)
+
+
+
-
- <>
- not equal
- numrange(1.1,2.2) <> numrange(1.1,2.3)
- t
-
+
+
+
+ anyrange @> anyrange
+ boolean
+
+
+ Does the first range contain the second?
+
+
+ int4range(2,4) @> int4range(2,3)
+ t
+
+
-
- <
- less than
- int4range(1,10) < int4range(2,3)
- t
-
+
+
+ anyrange @> anyelement
+ boolean
+
+
+ Does the range contain the element?
+
+
+ '[2011-01-01,2011-03-01)'::tsrange @> '2011-01-10'::timestamp
+ t
+
+
-
- >
- greater than
- int4range(1,10) > int4range(1,5)
- t
-
+
+
+ anyrange <@ anyrange
+ boolean
+
+
+ Is the first range contained by the second?
+
+
+ int4range(2,4) <@ int4range(1,7)
+ t
+
+
-
- <=
- less than or equal
- numrange(1.1,2.2) <= numrange(1.1,2.2)
- t
-
+
+
+ anyelement <@ anyrange
+ boolean
+
+
+ Is the element contained in the range?
+
+
+ 42 <@ int4range(1,7)
+ f
+
+
-
- >=
- greater than or equal
- numrange(1.1,2.2) >= numrange(1.1,2.0)
- t
-
+
+
+ anyrange && anyrange
+ boolean
+
+
+ Do the ranges overlap, that is, have any elements in common?
+
+
+ int8range(3,7) && int8range(4,12)
+ t
+
+
-
- @>
- contains range
- int4range(2,4) @> int4range(2,3)
- t
-
+
+
+ anyrange << anyrange
+ boolean
+
+
+ Is the first range strictly left of the second?
+
+
+ int8range(1,10) << int8range(100,110)
+ t
+
+
-
- @>
- contains element
- '[2011-01-01,2011-03-01)'::tsrange @> '2011-01-10'::timestamp
- t
-
+
+
+ anyrange >> anyrange
+ boolean
+
+
+ Is the first range strictly right of the second?
+
+
+ int8range(50,60) >> int8range(20,30)
+ t
+
+
-
- <@
- range is contained by
- int4range(2,4) <@ int4range(1,7)
- t
-
+
+
+ anyrange &< anyrange
+ boolean
+
+
+ Does the first range not extend to the right of the second?
+
+
+ int8range(1,20) &< int8range(18,20)
+ t
+
+
-
- <@
- element is contained by
- 42 <@ int4range(1,7)
- f
-
+
+
+ anyrange &> anyrange
+ boolean
+
+
+ Does the first range not extend to the left of the second?
+
+
+ int8range(7,20) &> int8range(5,10)
+ t
+
+
-
- &&
- overlap (have points in common)
- int8range(3,7) && int8range(4,12)
- t
-
+
+
+ anyrange -|- anyrange
+ boolean
+
+
+ Are the ranges adjacent?
+
+
+ numrange(1.1,2.2) -|- numrange(2.2,3.3)
+ t
+
+
-
- <<
- strictly left of
- int8range(1,10) << int8range(100,110)
- t
-
+
+
+ anyrange + anyrange
+ anyrange
+
+
+ Computes the union of the ranges. The ranges must overlap or be
+ adjacent, so that the union is a single range (but
+ see range_merge()).
+
+
+ numrange(5,15) + numrange(10,20)
+ [5,20)
+
+
-
- >>
- strictly right of
- int8range(50,60) >> int8range(20,30)
- t
-
+
+
+ anyrange * anyrange
+ anyrange
+
+
+ Computes the intersection of the ranges.
+
+
+ int8range(5,15) * int8range(10,20)
+ [10,15)
+
+
-
- &<
- does not extend to the right of
- int8range(1,20) &< int8range(18,20)
- t
-
-
-
- &>
- does not extend to the left of
- int8range(7,20) &> int8range(5,10)
- t
-
-
-
- -|-
- is adjacent to
- numrange(1.1,2.2) -|- numrange(2.2,3.3)
- t
-
-
-
- +
- union
- numrange(5,15) + numrange(10,20)
- [5,20)
-
-
-
- *
- intersection
- int8range(5,15) * int8range(10,20)
- [10,15)
-
-
-
- -
- difference
- int8range(5,15) - int8range(10,20)
- [5,10)
-
-
-
-
-
-
-
- The simple comparison operators <,
- >, <=, and
- >= compare the lower bounds first, and only if those
- are equal, compare the upper bounds. These comparisons are not usually
- very useful for ranges, but are provided to allow B-tree indexes to be
- constructed on ranges.
-
+
+
+ anyrange - anyrange
+ anyrange
+
+
+ Computes the difference of the ranges. The second range must not be
+ contained in the first in such a way that the difference would not be
+ a single range.
+
+
+ int8range(5,15) - int8range(10,20)
+ [5,10)
+
+
+
+
+
The left-of/right-of/adjacent operators always return false when an empty
@@ -18000,147 +18097,171 @@ NULL baz(3 rows)
before or after any other range.
-
- The union and difference operators will fail if the resulting range would
- need to contain two disjoint sub-ranges, as such a range cannot be
- represented.
-
-
shows the functions
available for use with range types.
-
- lower
-
-
- upper
-
-
- isempty
-
-
- lower_inc
-
-
- upper_inc
-
-
- lower_inf
-
-
- upper_inf
-
+
+ Range Functions
+
+
+
+
+ Function
+
+
+ Description
+
+
+ Example(s)
+
+
+
-
- Range Functions
-
-
-
- Function
- Return Type
- Description
- Example
- Result
-
-
-
-
-
-
- lower(anyrange)
-
-
- range's element type
- lower bound of range
- lower(numrange(1.1,2.2))
- 1.1
-
-
-
-
- upper(anyrange)
-
-
- range's element type
- upper bound of range
- upper(numrange(1.1,2.2))
- 2.2
-
-
-
-
- isempty(anyrange)
-
-
- boolean
- is the range empty?
- isempty(numrange(1.1,2.2))
- false
-
-
-
-
- lower_inc(anyrange)
-
-
- boolean
- is the lower bound inclusive?
- lower_inc(numrange(1.1,2.2))
- true
-
-
-
-
- upper_inc(anyrange)
-
-
- boolean
- is the upper bound inclusive?
- upper_inc(numrange(1.1,2.2))
- false
-
-
-
-
- lower_inf(anyrange)
-
-
- boolean
- is the lower bound infinite?
- lower_inf('(,)'::daterange)
- true
-
-
-
-
- upper_inf(anyrange)
-
-
- boolean
- is the upper bound infinite?
- upper_inf('(,)'::daterange)
- true
-
-
-
-
- range_merge(anyrange, anyrange)
-
-
- anyrange
- the smallest range which includes both of the given ranges
- range_merge('[1,2)'::int4range, '[3,4)'::int4range)
- [1,4)
-
-
-
-
+
+
+
+
+ lower
+
+ lower ( anyrange )
+ anyelement
+
+
+ Extracts the lower bound of the range (NULL if the
+ range is empty or the lower bound is infinite).
+
+
+ lower(numrange(1.1,2.2))
+ 1.1
+
+
+
+
+
+
+ upper
+
+ upper ( anyrange )
+ anyelement
+
+
+ Extracts the upper bound of the range (NULL if the
+ range is empty or the upper bound is infinite).
+
+
+ upper(numrange(1.1,2.2))
+ 2.2
+
+
+
+
+
+
+ isempty
+
+ isempty ( anyrange )
+ boolean
+
+
+ Is the range empty?
+
+
+ isempty(numrange(1.1,2.2))
+ f
+
+
+
+
+
+
+ lower_inc
+
+ lower_inc ( anyrange )
+ boolean
+
+
+ Is the range's lower bound inclusive?
+
+
+ lower_inc(numrange(1.1,2.2))
+ t
+
+
+
+
+
+
+ upper_inc
+
+ upper_inc ( anyrange )
+ boolean
+
+
+ Is the range's upper bound inclusive?
+
+
+ upper_inc(numrange(1.1,2.2))
+ f
+
+
+
+
+
+
+ lower_inf
+
+ lower_inf ( anyrange )
+ boolean
+
+
+ Is the range's lower bound infinite?
+
+
+ lower_inf('(,)'::daterange)
+ t
+
+
+
+
+
+
+ upper_inf
+
+ upper_inf ( anyrange )
+ boolean
+
+
+ Is the range's upper bound infinite?
+
+
+ upper_inf('(,)'::daterange)
+ t
+
+
+
+
+
+
+ range_merge
+
+ range_merge ( anyrange, anyrange )
+ anyrange
+
+
+ Computes the smallest range that includes both of the given ranges.
+
+
+ range_merge('[1,2)'::int4range, '[3,4)'::int4range)
+ [1,4)
+
+
+
+
+
- The lower and upper functions return null
- if the range is empty or the requested bound is infinite.
The lower_inc, upper_inc,
lower_inf, and upper_inf
functions all return false for an empty range.
@@ -18159,7 +18280,7 @@ NULL baz(3 rows)
Aggregate functions compute a single result
from a set of input values. The built-in general-purpose aggregate
functions are listed in
- and statistical aggregates in .
The built-in within-group ordered-set aggregate functions
are listed in
@@ -18173,359 +18294,389 @@ NULL baz(3 rows)
information.
-
- General-Purpose Aggregate Functions
+
+ Aggregate functions that support Partial Mode
+ are eligible to participate in various optimizations, such as parallel
+ aggregation.
+
-
-
-
- Function
- Argument Type(s)
- Return Type
- Partial Mode
- Description
-
-
+
+ General-Purpose Aggregate Functions
+
+
+
+
+
+
+ Function
+
+
+ Description
+
+ Partial Mode
+
+
-
-
-
-
- array_agg
-
- array_agg(expression)
-
-
- any non-array type
-
-
- array of the argument type
-
- No
- input values, including nulls, concatenated into an array
-
+
+
+
+
+ array_agg
+
+ array_agg ( anynonarray )
+ anyarray
+
+
+ Collects all the input values, including nulls, into an array.
+
+ No
+
-
-
- array_agg(expression)
-
-
- any array type
-
-
- same as argument data type
-
- No
- input arrays concatenated into array of one higher dimension
- (inputs must all have same dimensionality,
- and cannot be empty or null)
-
+
+
+ array_agg ( anyarray )
+ anyarray
+
+
+ Concatenates all the input arrays into an array of one higher
+ dimension. (The inputs must all have the same dimensionality, and
+ cannot be empty or null.)
+
+ No
+
-
-
-
- average
-
-
- avg
-
- avg(expression)
-
-
- smallint, int,
- bigint, real, double
- precision, numeric, or interval
-
-
- numeric for any integer-type argument,
- double precision for a floating-point argument,
- otherwise the same as the argument data type
-
- Yes
- the average (arithmetic mean) of all non-null input values
-
+
+
+
+ average
+
+
+ avg
+
+ avg ( smallint )
+ numeric
+
+
+ avg ( integer )
+ numeric
+
+
+ avg ( bigint )
+ numeric
+
+
+ avg ( numeric )
+ numeric
+
+
+ avg ( real )
+ double precision
+
+
+ avg ( double precision )
+ double precision
+
+
+ avg ( interval )
+ interval
+
+
+ Computes the average (arithmetic mean) of all the non-null input
+ values.
+
+ Yes
+
-
-
-
- bit_and
-
- bit_and(expression)
-
-
- smallint, int, bigint, or
- bit
-
-
- same as argument data type
-
- Yes
- the bitwise AND of all non-null input values, or null if none
-
+
+
+
+ bit_and
+
+ bit_and ( smallint )
+ smallint
+
+
+ bit_and ( integer )
+ integer
+
+
+ bit_and ( bigint )
+ bigint
+
+
+ bit_and ( bit )
+ bit
+
+
+ Computes the bitwise AND of all non-null input values.
+
+ Yes
+
-
-
-
- bit_or
-
- bit_or(expression)
-
-
- smallint, int, bigint, or
- bit
-
-
- same as argument data type
-
- Yes
- the bitwise OR of all non-null input values, or null if none
-
+
+
+
+ bit_or
+
+ bit_or ( smallint )
+ smallint
+
+
+ bit_or ( integer )
+ integer
+
+
+ bit_or ( bigint )
+ bigint
+
+
+ bit_or ( bit )
+ bit
+
+
+ Computes the bitwise OR of all non-null input values.
+
+ Yes
+
-
-
-
- bool_and
-
- bool_and(expression)
-
-
- bool
-
-
- bool
-
- Yes
- true if all input values are true, otherwise false
-
+
+
+
+ bool_and
+
+ bool_and ( boolean )
+ boolean
+
+
+ Returns true if all non-null input values are true, otherwise false.
+
+ Yes
+
-
-
-
- bool_or
-
- bool_or(expression)
-
-
- bool
-
-
- bool
-
- Yes
- true if at least one input value is true, otherwise false
-
+
+
+
+ bool_or
+
+ bool_or ( boolean )
+ boolean
+
+
+ Returns true if any non-null input value is true, otherwise false.
+
+ Yes
+
-
-
-
- count
-
- count(*)
-
-
- bigint
- Yes
- number of input rows
-
+
+
+
+ count
+
+ count ( * )
+ bigint
+
+
+ Computes the number of input rows.
+
+ Yes
+
-
- count(expression)
- any
- bigint
- Yes
-
- number of input rows for which the value of expression is not null
-
-
+
+
+ count ( "any" )
+ bigint
+
+
+ Computes the number of input rows in which the input value is not
+ null.
+
+ Yes
+
-
-
-
- every
-
- every(expression)
-
-
- bool
-
-
- bool
-
- Yes
- equivalent to bool_and
-
+
+
+
+ every
+
+ every ( boolean )
+ boolean
+
+
+ This is the SQL standard's equivalent to bool_and.
+
+ Yes
+
-
-
-
- json_agg
-
- json_agg(expression)
-
-
- any
-
-
- json
-
- No
- aggregates values, including nulls, as a JSON array
-
+
+
+
+ json_agg
+
+ json_agg ( anyelement )
+ json
+
+
+
+ jsonb_agg
+
+ jsonb_agg ( anyelement )
+ jsonb
+
+
+ Collects all the input values, including nulls, into a JSON array.
+ Values are converted to JSON as per to_json
+ or to_jsonb.
+
+ No
+
-
-
-
- jsonb_agg
-
- jsonb_agg(expression)
-
-
- any
-
-
- jsonb
-
- No
- aggregates values, including nulls, as a JSON array
-
+
+
+
+ json_object_agg
+
+ json_object_agg ( key
+ "any", value
+ "any" )
+ json
+
+
+
+ jsonb_object_agg
+
+ jsonb_object_agg ( key
+ "any", value
+ "any" )
+ jsonb
+
+
+ Collects all the key/value pairs into a JSON object. Key arguments
+ are coerced to text; value arguments are converted as
+ per to_json or to_jsonb.
+ Values can be null, but not keys.
+
+ No
+
-
-
-
- json_object_agg
-
- json_object_agg(name, value)
-
-
- (any, any)
-
-
- json
-
- No
- aggregates name/value pairs as a JSON object; values can be
- null, but not names
-
+
+
+
+ max
+
+ max ( see text )
+ same as input type
+
+
+ Computes the maximum of the non-null input
+ values. Available for any numeric, string, date/time, or enum type,
+ as well as inet, interval,
+ money, oid, pg_lsn,
+ tid,
+ and arrays of any of these types.
+
+ Yes
+
-
-
-
- jsonb_object_agg
-
- jsonb_object_agg(name, value)
-
-
- (any, any)
-
-
- jsonb
-
- No
- aggregates name/value pairs as a JSON object; values can be
- null, but not names
-
+
+
+
+ min
+
+ min ( see text )
+ same as input type
+
+
+ Computes the minimum of the non-null input
+ values. Available for any numeric, string, date/time, or enum type,
+ as well as inet, interval,
+ money, oid, pg_lsn,
+ tid,
+ and arrays of any of these types.
+
+ Yes
+
-
-
-
- max
-
- max(expression)
-
- any numeric, string, date/time, network, pg_lsn, or enum type,
- or arrays of these types
- same as argument type
- Yes
-
- maximum value of expression across all non-null input
- values
-
-
+
+
+
+ string_agg
+
+ string_agg ( value
+ text, delimiter text )
+ text
+
+
+ string_agg ( value
+ bytea, delimiter bytea )
+ bytea
+
+
+ Concatenates the non-null input values into a string. Each value
+ after the first is preceded by the
+ corresponding delimiter (if it's not null).
+
+ No
+
-
-
-
- min
-
- min(expression)
-
- any numeric, string, date/time, network, pg_lsn, or enum type,
- or arrays of these types
- same as argument type
- Yes
-
- minimum value of expression across all non-null input
- values
-
-
+
+
+
+ sum
+
+ sum ( smallint )
+ bigint
+
+
+ sum ( integer )
+ bigint
+
+
+ sum ( bigint )
+ numeric
+
+
+ sum ( numeric )
+ numeric
+
+
+ sum ( real )
+ real
+
+
+ sum ( double precision )
+ double precision
+
+
+ sum ( interval )
+ interval
+
+
+ sum ( money )
+ money
+
+
+ Computes the sum of the non-null input values.
+
+ Yes
+
-
-
-
- string_agg
-
-
- string_agg(expression,
- delimiter)
-
-
-
- (text, text) or (bytea, bytea)
-
-
- same as argument types
-
- No
- non-null input values concatenated into a string, separated by delimiter
-
-
-
-
-
- sum
-
- sum(expression)
-
-
- smallint, int,
- bigint, real, double
- precision, numeric,
- interval, or money
-
-
- bigint for smallint or
- int arguments, numeric for
- bigint arguments, otherwise the same as the
- argument data type
-
- Yes
- sum of expression
- across all non-null input values
-
-
-
-
-
- xmlagg
-
- xmlagg(expression)
-
-
- xml
-
-
- xml
-
- No
- concatenation of non-null XML values
- (see also )
-
-
-
-
+
+
+
+ xmlagg
+
+ xmlagg ( xml )
+ xml
+
+
+ Concatenates the non-null XML input values (see
+ ).
+
+ No
+
+
+
+
It should be noted that except for count,
@@ -18537,52 +18688,6 @@ NULL baz(3 rows)
substitute zero or an empty array for null when necessary.
-
- Aggregate functions which support Partial Mode
- are eligible to participate in various optimizations, such as parallel
- aggregation.
-
-
-
-
- ANY
-
-
- SOME
-
-
- Boolean aggregates bool_and and
- bool_or correspond to standard SQL aggregates
- every and any or
- some.
- As for any and some,
- it seems that there is an ambiguity built into the standard syntax:
-
-SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...;
-
- Here ANY can be considered either as introducing
- a subquery, or as being an aggregate function, if the subquery
- returns one row with a Boolean value.
- Thus the standard name cannot be given to these aggregates.
-
-
-
-
-
- Users accustomed to working with other SQL database management
- systems might be disappointed by the performance of the
- count aggregate when it is applied to the
- entire table. A query like:
-
-SELECT count(*) FROM sometable;
-
- will require effort proportional to the size of the table:
- PostgreSQL will need to scan either the
- entire table or the entirety of an index which includes all rows in
- the table.
-
-
-
The aggregate functions array_agg,
json_agg, jsonb_agg,
@@ -18606,11 +18711,58 @@ SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
subquery's output to be reordered before the aggregate is computed.
+
+
+ ANY
+
+
+ SOME
+
+
+ The boolean aggregates bool_and and
+ bool_or correspond to the standard SQL aggregates
+ every and any or
+ some.
+ PostgreSQL
+ supports every, but not any
+ or some, because there is an ambiguity built into
+ the standard syntax:
+
+SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...;
+
+ Here ANY can be considered either as introducing
+ a subquery, or as being an aggregate function, if the subquery
+ returns one row with a Boolean value.
+ Thus the standard name cannot be given to these aggregates.
+
+
+
+
+
+ Users accustomed to working with other SQL database management
+ systems might be disappointed by the performance of the
+ count aggregate when it is applied to the
+ entire table. A query like:
+
+SELECT count(*) FROM sometable;
+
+ will require effort proportional to the size of the table:
+ PostgreSQL will need to scan either the
+ entire table or the entirety of an index that includes all rows in
+ the table.
+
+
+
shows
aggregate functions typically used in statistical analysis.
(These are separated out merely to avoid cluttering the listing
- of more-commonly-used aggregates.) Where the description mentions
+ of more-commonly-used aggregates.) Functions shown as
+ accepting numeric_type are available for all
+ the types smallint, integer,
+ bigint, numeric, real,
+ and double precision.
+ Where the description mentions
N, it means the
number of input rows for which all the input expressions are non-null.
In all cases, null is returned if the computation is meaningless,
@@ -18624,412 +18776,353 @@ SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
linear regression
-
- Aggregate Functions for Statistics
+
+ Aggregate Functions for Statistics
+
+
+
+
+
+
+ Function
+
+
+ Description
+
+ Partial Mode
+
+
-
-
-
- Function
- Argument Type
- Return Type
- Partial Mode
- Description
-
-
+
+
+
+
+ correlation
+
+
+ corr
+
+ corr ( Y double precision, X double precision )
+ double precision
+
+
+ Computes the correlation coefficient.
+
+ Yes
+
-
+
+
+
+ covariance
+ population
+
+
+ covar_pop
+
+ covar_pop ( Y double precision, X double precision )
+ double precision
+
+
+ Computes the population covariance.
+
+ Yes
+
-
-
-
- correlation
-
-
- corr
-
- corr(Y, X)
-
-
- double precision
-
-
- double precision
-
- Yes
- correlation coefficient
-
+
+
+
+ covariance
+ sample
+
+
+ covar_samp
+
+ covar_samp ( Y double precision, X double precision )
+ double precision
+
+
+ Computes the sample covariance.
+
+ Yes
+
-
-
-
- covariance
- population
-
-
- covar_pop
-
- covar_pop(Y, X)
-
-
- double precision
-
-
- double precision
-
- Yes
- population covariance
-
+
+
+
+ regr_avgx
+
+ regr_avgx ( Y double precision, X double precision )
+ double precision
+
+
+ Computes the average of the independent variable,
+ sum(X)/N.
+
+ Yes
+
-
-
-
- covariance
- sample
-
-
- covar_samp
-
- covar_samp(Y, X)
-
-
- double precision
-
-
- double precision
-
- Yes
- sample covariance
-
+
+
+
+ regr_avgy
+
+ regr_avgy ( Y double precision, X double precision )
+ double precision
+
+
+ Computes the average of the dependent variable,
+ sum(Y)/N.
+
+ Yes
+
-
-
-
- regr_avgx
-
- regr_avgx(Y, X)
-
-
- double precision
-
-
- double precision
-
- Yes
- average of the independent variable
- (sum(X)/N)
-
+
+
+
+ regr_count
+
+ regr_count ( Y double precision, X double precision )
+ bigint
+
+
+ Computes the number of rows in which both inputs are non-null.
+
+ Yes
+
-
-
-
- regr_avgy
-
- regr_avgy(Y, X)
-
-
- double precision
-
-
- double precision
-
- Yes
- average of the dependent variable
- (sum(Y)/N)
-
+
+
+
+ regression intercept
+
+
+ regr_intercept
+
+ regr_intercept ( Y double precision, X double precision )
+ double precision
+
+
+ Computes the y-intercept of the least-squares-fit linear equation
+ determined by the
+ (X, Y) pairs.
+
+ Yes
+
-
-
-
- regr_count
-
- regr_count(Y, X)
-
-
- double precision
-
-
- bigint
-
- Yes
- number of input rows in which both expressions are nonnull
-
+
+
+
+ regr_r2
+
+ regr_r2 ( Y double precision, X double precision )
+ double precision
+
+
+ Computes the square of the correlation coefficient.
+
+ Yes
+
-
-
-
- regression intercept
-
-
- regr_intercept
-
- regr_intercept(Y, X)
-
-
- double precision
-
-
- double precision
-
- Yes
- y-intercept of the least-squares-fit linear equation
- determined by the (X, Y) pairs
-
+
+
+
+ regression slope
+
+
+ regr_slope
+
+ regr_slope ( Y double precision, X double precision )
+ double precision
+
+
+ Computes the slope of the least-squares-fit linear equation determined
+ by the (X, Y)
+ pairs.
+
+ Yes
+
-
-
-
- regr_r2
-
- regr_r2(Y, X)
-
-
- double precision
-
-
- double precision
-
- Yes
- square of the correlation coefficient
-
+
+
+
+ regr_sxx
+
+ regr_sxx ( Y double precision, X double precision )
+ double precision
+
+
+ Computes the sum of squares
of the independent
+ variable,
+ sum(X^2) - sum(X)^2/N.
+
+ Yes
+
-
-
-
- regression slope
-
-
- regr_slope
-
- regr_slope(Y, X)
-
-
- double precision
-
-
- double precision
-
- Yes
- slope of the least-squares-fit linear equation determined
- by the (X,
- Y) pairs
-
+
+
+
+ regr_sxy
+
+ regr_sxy ( Y double precision, X double precision )
+ double precision
+
+
+ Computes the sum of products
of independent times
+ dependent variables,
+ sum(X*Y) - sum(X) * sum(Y)/N.
+
+ Yes
+
-
-
-
- regr_sxx
-
- regr_sxx(Y, X)
-
-
- double precision
-
-
- double precision
-
- Yes
- sum(X^2) - sum(X)^2/N (sum of
- squares
of the independent variable)
-
+
+
+
+ regr_syy
+
+ regr_syy ( Y double precision, X double precision )
+ double precision
+
+
+ Computes the sum of squares
of the dependent
+ variable,
+ sum(Y^2) - sum(Y)^2/N.
+
+ Yes
+
-
-
-
- regr_sxy
-
- regr_sxy(Y, X)
-
-
- double precision
-
-
- double precision
-
- Yes
- sum(X*Y) - sum(X) * sum(Y)/N (sum of
- products
of independent times dependent
- variable)
-
+
+
+
+ standard deviation
+
+
+ stddev
+
+ stddev ( numeric_type )
+ double precision
+ for real or double precision,
+ otherwise numeric
+
+
+ This is a historical alias for stddev_samp.
+
+ Yes
+
-
-
-
- regr_syy
-
- regr_syy(Y, X)
-
-
- double precision
-
-
- double precision
-
- Yes
- sum(Y^2) - sum(Y)^2/N (sum of
- squares
of the dependent variable)
-
+
+
+
+ standard deviation
+ population
+
+
+ stddev_pop
+
+ stddev_pop ( numeric_type )
+ double precision
+ for real or double precision,
+ otherwise numeric
+
+
+ Computes the population standard deviation of the input values.
+
+ Yes
+
-
-
-
- standard deviation
-
-
- stddev
-
- stddev(expression)
-
-
- smallint, int,
- bigint, real, double
- precision, or numeric
-
-
- double precision for floating-point arguments,
- otherwise numeric
-
- Yes
- historical alias for stddev_samp
-
+
+
+
+ standard deviation
+ sample
+
+
+ stddev_samp
+
+ stddev_samp ( numeric_type )
+ double precision
+ for real or double precision,
+ otherwise numeric
+
+
+ Computes the sample standard deviation of the input values.
+
+ Yes
+
-
-
-
- standard deviation
- population
-
-
- stddev_pop
-
- stddev_pop(expression)
-
-
- smallint, int,
- bigint, real, double
- precision, or numeric
-
-
- double precision for floating-point arguments,
- otherwise numeric
-
- Yes
- population standard deviation of the input values
-
+
+
+
+ variance
+
+ variance ( numeric_type )
+ double precision
+ for real or double precision,
+ otherwise numeric
+
+
+ This is a historical alias for var_samp.
+
+ Yes
+
-
-
-
- standard deviation
- sample
-
-
- stddev_samp
-
- stddev_samp(expression)
-
-
- smallint, int,
- bigint, real, double
- precision, or numeric
-
-
- double precision for floating-point arguments,
- otherwise numeric
-
- Yes
- sample standard deviation of the input values
-
+
+
+
+ variance
+ population
+
+
+ var_pop
+
+ var_pop ( numeric_type )
+ double precision
+ for real or double precision,
+ otherwise numeric
+
+
+ Computes the population variance of the input values (square of the
+ population standard deviation).
+
+ Yes
+
-
-
-
- variance
-
- variance(expression)
-
-
- smallint, int,
- bigint, real, double
- precision, or numeric
-
-
- double precision for floating-point arguments,
- otherwise numeric
-
- Yes
- historical alias for var_samp
-
-
-
-
-
- variance
- population
-
-
- var_pop
-
- var_pop(expression)
-
-
- smallint, int,
- bigint, real, double
- precision, or numeric
-
-
- double precision for floating-point arguments,
- otherwise numeric
-
- Yes
- population variance of the input values (square of the population standard deviation)
-
-
-
-
-
- variance
- sample
-
-
- var_samp
-
- var_samp(expression)
-
-
- smallint, int,
- bigint, real, double
- precision, or numeric
-
-
- double precision for floating-point arguments,
- otherwise numeric
-
- Yes
- sample variance of the input values (square of the sample standard deviation)
-
-
-
-
+
+
+
+ variance
+ sample
+
+
+ var_samp
+
+ var_samp ( numeric_type )
+ double precision
+ for real or double precision,
+ otherwise numeric
+
+
+ Computes the sample variance of the input values (square of the sample
+ standard deviation).
+
+ Yes
+
+
+
+
shows some
aggregate functions that use the ordered-set aggregate
syntax. These functions are sometimes referred to as inverse
- distribution
functions.
+ distribution functions. Their aggregated input is introduced by
+ ORDER BY, and they may also take a direct
+ argument that is not aggregated, but is computed only once.
+ All these functions ignore null values in their aggregated input.
+ For those that take a fraction parameter, the
+ fraction value must be between 0 and 1; an error is thrown if not.
+ However, a null fraction value simply produces a
+ null result.
@@ -19040,148 +19133,118 @@ SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
inverse distribution
-
- Ordered-Set Aggregate Functions
+
+ Ordered-Set Aggregate Functions
+
+
+
+
+
+
+ Function
+
+
+ Description
+
+ Partial Mode
+
+
-
-
-
- Function
- Direct Argument Type(s)
- Aggregated Argument Type(s)
- Return Type
- Partial Mode
- Description
-
-
+
+
+
+
+ mode
+ statistical
+
+ mode () WITHIN GROUP ( ORDER BY anyelement )
+ anyelement
+
+
+ Computes the mode, the most frequent
+ value of the aggregated argument (arbitrarily choosing the first one
+ if there are multiple equally-frequent values). The aggregated
+ argument must be of a sortable type.
+
+ No
+
-
+
+
+
+ percentile
+ continuous
+
+ percentile_cont ( fraction double precision ) WITHIN GROUP ( ORDER BY double precision )
+ double precision
+
+
+ percentile_cont ( fraction double precision ) WITHIN GROUP ( ORDER BY interval )
+ interval
+
+
+ Computes the continuous percentile, a value
+ corresponding to the specified fraction
+ within the ordered set of aggregated argument values. This will
+ interpolate between adjacent input items if needed.
+
+ No
+
-
-
-
- mode
- statistical
-
- mode() WITHIN GROUP (ORDER BY sort_expression)
-
-
-
-
- any sortable type
-
-
- same as sort expression
-
- No
-
- returns the most frequent input value (arbitrarily choosing the first
- one if there are multiple equally-frequent results)
-
-
+
+
+ percentile_cont ( fractions double precision[] ) WITHIN GROUP ( ORDER BY double precision )
+ double precision[]
+
+
+ percentile_cont ( fractions double precision[] ) WITHIN GROUP ( ORDER BY interval )
+ interval[]
+
+
+ Computes multiple continuous percentiles. The result is an array of
+ the same dimensions as the fractions
+ parameter, with each non-null element replaced by the (possibly
+ interpolated) value corresponding to that percentile.
+
+ No
+
-
-
-
- percentile
- continuous
-
- percentile_cont(fraction) WITHIN GROUP (ORDER BY sort_expression)
-
-
- double precision
-
-
- double precision or interval
-
-
- same as sort expression
-
- No
-
- continuous percentile: returns a value corresponding to the specified
- fraction in the ordering, interpolating between adjacent input items if
- needed
-
-
+
+
+
+ percentile
+ discrete
+
+ percentile_disc ( fraction double precision ) WITHIN GROUP ( ORDER BY anyelement )
+ anyelement
+
+
+ Computes the discrete percentile, the first
+ value within the ordered set of aggregated argument values whose
+ position in the ordering equals or exceeds the
+ specified fraction. The aggregated
+ argument must be of a sortable type.
+
+ No
+
-
-
- percentile_cont(fractions) WITHIN GROUP (ORDER BY sort_expression)
-
-
- double precision[]
-
-
- double precision or interval
-
-
- array of sort expression's type
-
- No
-
- multiple continuous percentile: returns an array of results matching
- the shape of the fractions parameter, with each
- non-null element replaced by the value corresponding to that percentile
-
-
-
-
-
-
- percentile
- discrete
-
- percentile_disc(fraction) WITHIN GROUP (ORDER BY sort_expression)
-
-
- double precision
-
-
- any sortable type
-
-
- same as sort expression
-
- No
-
- discrete percentile: returns the first input value whose position in
- the ordering equals or exceeds the specified fraction
-
-
-
-
-
- percentile_disc(fractions) WITHIN GROUP (ORDER BY sort_expression)
-
-
- double precision[]
-
-
- any sortable type
-
-
- array of sort expression's type
-
- No
-
- multiple discrete percentile: returns an array of results matching the
- shape of the fractions parameter, with each non-null
- element replaced by the input value corresponding to that percentile
-
-
-
-
-
-
-
-
- All the aggregates listed in
- ignore null values in their sorted input. For those that take
- a fraction parameter, the fraction value must be
- between 0 and 1; an error is thrown if not. However, a null fraction value
- simply produces a null result.
-
+
+
+ percentile_disc ( fractions double precision[] ) WITHIN GROUP ( ORDER BY anyelement )
+ anyarray
+
+
+ Computes multiple discrete percentiles. The result is an array of the
+ same dimensions as the fractions parameter,
+ with each non-null element replaced by the input value corresponding
+ to that percentile.
+ The aggregated argument must be of a sortable type.
+
+ No
+
+
+
+
hypothetical-set aggregate
@@ -19189,132 +19252,15 @@ SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
- Each of the aggregates listed in
+ Each of the hypothetical-set
aggregates listed in
is associated with a
window function of the same name defined in
- . In each case, the aggregate result
+ . In each case, the aggregate's result
is the value that the associated window function would have
returned for the hypothetical
row constructed from
args, if such a row had been added to the sorted
- group of rows computed from the sorted_args.
-
-
-
- Hypothetical-Set Aggregate Functions
-
-
-
-
- Function
- Direct Argument Type(s)
- Aggregated Argument Type(s)
- Return Type
- Partial Mode
- Description
-
-
-
-
-
-
-
-
- rank
- hypothetical
-
- rank(args) WITHIN GROUP (ORDER BY sorted_args)
-
-
- VARIADIC "any"
-
-
- VARIADIC "any"
-
-
- bigint
-
- No
-
- rank of the hypothetical row, with gaps for duplicate rows
-
-
-
-
-
-
- dense_rank
- hypothetical
-
- dense_rank(args) WITHIN GROUP (ORDER BY sorted_args)
-
-
- VARIADIC "any"
-
-
- VARIADIC "any"
-
-
- bigint
-
- No
-
- rank of the hypothetical row, without gaps
-
-
-
-
-
-
- percent_rank
- hypothetical
-
- percent_rank(args) WITHIN GROUP (ORDER BY sorted_args)
-
-
- VARIADIC "any"
-
-
- VARIADIC "any"
-
-
- double precision
-
- No
-
- relative rank of the hypothetical row, ranging from 0 to 1
-
-
-
-
-
-
- cume_dist
- hypothetical
-
- cume_dist(args) WITHIN GROUP (ORDER BY sorted_args)
-
-
- VARIADIC "any"
-
-
- VARIADIC "any"
-
-
- double precision
-
- No
-
- relative rank of the hypothetical row, ranging from
- 1/N to 1
-
-
-
-
-
-
-
-
- For each of these hypothetical-set aggregates, the list of direct arguments
+ group of rows represented by the sorted_args.
+ For each of these functions, the list of direct arguments
given in args must match the number and types of
the aggregated arguments given in sorted_args.
Unlike most built-in aggregates, these aggregates are not strict, that is
@@ -19322,48 +19268,137 @@ SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
to the rule specified in the ORDER BY clause.
+
+ Hypothetical-Set Aggregate Functions
+
+
+
+
+
+
+ Function
+
+
+ Description
+
+ Partial Mode
+
+
+
+
+
+
+
+ rank
+ hypothetical
+
+ rank ( args ) WITHIN GROUP ( ORDER BY sorted_args )
+ bigint
+
+
+ Computes the rank of the hypothetical row, with gaps; that is, the row
+ number of the first row in its peer group.
+
+ No
+
+
+
+
+
+ dense_rank
+ hypothetical
+
+ dense_rank ( args ) WITHIN GROUP ( ORDER BY sorted_args )
+ bigint
+
+
+ Computes the rank of the hypothetical row, without gaps; this function
+ effectively counts peer groups.
+
+ No
+
+
+
+
+
+ percent_rank
+ hypothetical
+
+ percent_rank ( args ) WITHIN GROUP ( ORDER BY sorted_args )
+ double precision
+
+
+ Computes the relative rank of the hypothetical row, that is
+ (rank - 1) / (total rows - 1).
+ The value thus ranges from 0 to 1 inclusive.
+
+ No
+
+
+
+
+
+ cume_dist
+ hypothetical
+
+ cume_dist ( args ) WITHIN GROUP ( ORDER BY sorted_args )
+ double precision
+
+
+ Computes the cumulative distribution, that is (number of rows
+ preceding or peers with hypothetical row) / (total rows). The value
+ thus ranges from 1/N to 1.
+
+ No
+
+
+
+
+
Grouping Operations
+
+
+
+
+ Function
+
+
+ Description
+
+
+
-
-
-
- Function
- Return Type
- Description
-
-
-
-
-
-
-
-
- GROUPING
-
- GROUPING(args...)
-
-
- integer
-
-
- Integer bit mask indicating which arguments are not being included in the current
- grouping set
-
-
-
-
-
+
+
+
+
+ GROUPING
+
+ GROUPING ( group_by_expression(s) )
+ integer
+
+
+ Returns a bit mask indicating which GROUP BY
+ expressions are not included in the current grouping set.
+ Bits are assigned with the rightmost argument corresponding to the
+ least-significant bit; each bit is 0 if the corresponding expression
+ is included in the grouping criteria of the grouping set generating
+ the current result row, and 1 if it is not included.
+
+
+
+
+
- Grouping operations are used in conjunction with grouping sets (see
- ) to distinguish result rows. The
- arguments to the GROUPING operation are not actually evaluated,
- but they must match exactly expressions given in the GROUP BY
- clause of the associated query level. Bits are assigned with the rightmost
- argument being the least-significant bit; each bit is 0 if the corresponding
- expression is included in the grouping criteria of the grouping set generating
- the result row, and 1 if it is not. For example:
+ The grouping operations shown in
+ are used in conjunction with
+ grouping sets (see ) to distinguish
+ result rows. The arguments to the GROUPING function
+ are not actually evaluated, but they must exactly match expressions given
+ in the GROUP BY clause of the associated query level.
+ For example:
=> SELECT * FROM items_sold;
make | model | sales
@@ -19386,6 +19421,14 @@ SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
| | 3 | 50
(7 rows)
+ Here, the grouping value 0 in the
+ first four rows shows that those have been grouped normally, over both the
+ grouping columns. The value 1 indicates
+ that model was not grouped by in the next-to-last two
+ rows, and the value 3 indicates that
+ neither make nor model was grouped
+ by in the last row (which therefore is an aggregate over all the input
+ rows).