| <!-- doc/src/sgml/func.sgml --> |
| |
| <chapter id="functions"> |
| <title>Functions and Operators</title> |
| |
| <indexterm zone="functions"> |
| <primary>function</primary> |
| </indexterm> |
| |
| <indexterm zone="functions"> |
| <primary>operator</primary> |
| </indexterm> |
| |
| <para> |
| <productname>PostgreSQL</productname> provides a large number of |
| functions and operators for the built-in data types. This chapter |
| describes most of them, although additional special-purpose functions |
| appear in relevant sections of the manual. Users can also |
| define their own functions and operators, as described in |
| <xref linkend="server-programming"/>. The |
| <application>psql</application> commands <command>\df</command> and |
| <command>\do</command> can be used to list all |
| available functions and operators, respectively. |
| </para> |
| |
| <para> |
| The notation used throughout this chapter to describe the argument and |
| result data types of a function or operator is like this: |
| <synopsis> |
| <function>repeat</function> ( <type>text</type>, <type>integer</type> ) <returnvalue>text</returnvalue> |
| </synopsis> |
| which says that the function <function>repeat</function> takes one text and |
| one integer argument and returns a result of type text. The right arrow |
| is also used to indicate the result of an example, thus: |
| <programlisting> |
| repeat('Pg', 4) <returnvalue>PgPgPgPg</returnvalue> |
| </programlisting> |
| </para> |
| |
| <para> |
| If you are concerned about portability then 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 |
| <acronym>SQL</acronym> standard. Some of this extended functionality |
| is present in other <acronym>SQL</acronym> database management |
| systems, and in many cases this functionality is compatible and |
| consistent between the various implementations. |
| </para> |
| |
| |
| <sect1 id="functions-logical"> |
| <title>Logical Operators</title> |
| |
| <indexterm zone="functions-logical"> |
| <primary>operator</primary> |
| <secondary>logical</secondary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>Boolean</primary> |
| <secondary>operators</secondary> |
| <see>operators, logical</see> |
| </indexterm> |
| |
| <para> |
| The usual logical operators are available: |
| |
| <indexterm> |
| <primary>AND (operator)</primary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>OR (operator)</primary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>NOT (operator)</primary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>conjunction</primary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>disjunction</primary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>negation</primary> |
| </indexterm> |
| |
| <synopsis> |
| <type>boolean</type> <literal>AND</literal> <type>boolean</type> <returnvalue>boolean</returnvalue> |
| <type>boolean</type> <literal>OR</literal> <type>boolean</type> <returnvalue>boolean</returnvalue> |
| <literal>NOT</literal> <type>boolean</type> <returnvalue>boolean</returnvalue> |
| </synopsis> |
| |
| <acronym>SQL</acronym> uses a three-valued logic system with true, |
| false, and <literal>null</literal>, which represents <quote>unknown</quote>. |
| Observe the following truth tables: |
| |
| <informaltable> |
| <tgroup cols="4"> |
| <thead> |
| <row> |
| <entry><replaceable>a</replaceable></entry> |
| <entry><replaceable>b</replaceable></entry> |
| <entry><replaceable>a</replaceable> AND <replaceable>b</replaceable></entry> |
| <entry><replaceable>a</replaceable> OR <replaceable>b</replaceable></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry>TRUE</entry> |
| <entry>TRUE</entry> |
| <entry>TRUE</entry> |
| <entry>TRUE</entry> |
| </row> |
| |
| <row> |
| <entry>TRUE</entry> |
| <entry>FALSE</entry> |
| <entry>FALSE</entry> |
| <entry>TRUE</entry> |
| </row> |
| |
| <row> |
| <entry>TRUE</entry> |
| <entry>NULL</entry> |
| <entry>NULL</entry> |
| <entry>TRUE</entry> |
| </row> |
| |
| <row> |
| <entry>FALSE</entry> |
| <entry>FALSE</entry> |
| <entry>FALSE</entry> |
| <entry>FALSE</entry> |
| </row> |
| |
| <row> |
| <entry>FALSE</entry> |
| <entry>NULL</entry> |
| <entry>FALSE</entry> |
| <entry>NULL</entry> |
| </row> |
| |
| <row> |
| <entry>NULL</entry> |
| <entry>NULL</entry> |
| <entry>NULL</entry> |
| <entry>NULL</entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </informaltable> |
| |
| <informaltable> |
| <tgroup cols="2"> |
| <thead> |
| <row> |
| <entry><replaceable>a</replaceable></entry> |
| <entry>NOT <replaceable>a</replaceable></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry>TRUE</entry> |
| <entry>FALSE</entry> |
| </row> |
| |
| <row> |
| <entry>FALSE</entry> |
| <entry>TRUE</entry> |
| </row> |
| |
| <row> |
| <entry>NULL</entry> |
| <entry>NULL</entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </informaltable> |
| </para> |
| |
| <para> |
| The operators <literal>AND</literal> and <literal>OR</literal> are |
| commutative, that is, you can switch the left and right operands |
| without affecting the result. (However, it is not guaranteed that |
| the left operand is evaluated before the right operand. See <xref |
| linkend="syntax-express-eval"/> for more information about the |
| order of evaluation of subexpressions.) |
| </para> |
| </sect1> |
| |
| <sect1 id="functions-comparison"> |
| <title>Comparison Functions and Operators</title> |
| |
| <indexterm zone="functions-comparison"> |
| <primary>comparison</primary> |
| <secondary>operators</secondary> |
| </indexterm> |
| |
| <para> |
| The usual comparison operators are available, as shown in <xref |
| linkend="functions-comparison-op-table"/>. |
| </para> |
| |
| <table id="functions-comparison-op-table"> |
| <title>Comparison Operators</title> |
| <tgroup cols="2"> |
| <thead> |
| <row> |
| <entry>Operator</entry> |
| <entry>Description</entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry> |
| <replaceable>datatype</replaceable> <literal><</literal> <replaceable>datatype</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </entry> |
| <entry>Less than</entry> |
| </row> |
| |
| <row> |
| <entry> |
| <replaceable>datatype</replaceable> <literal>></literal> <replaceable>datatype</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </entry> |
| <entry>Greater than</entry> |
| </row> |
| |
| <row> |
| <entry> |
| <replaceable>datatype</replaceable> <literal><=</literal> <replaceable>datatype</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </entry> |
| <entry>Less than or equal to</entry> |
| </row> |
| |
| <row> |
| <entry> |
| <replaceable>datatype</replaceable> <literal>>=</literal> <replaceable>datatype</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </entry> |
| <entry>Greater than or equal to</entry> |
| </row> |
| |
| <row> |
| <entry> |
| <replaceable>datatype</replaceable> <literal>=</literal> <replaceable>datatype</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </entry> |
| <entry>Equal</entry> |
| </row> |
| |
| <row> |
| <entry> |
| <replaceable>datatype</replaceable> <literal><></literal> <replaceable>datatype</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </entry> |
| <entry>Not equal</entry> |
| </row> |
| |
| <row> |
| <entry> |
| <replaceable>datatype</replaceable> <literal>!=</literal> <replaceable>datatype</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </entry> |
| <entry>Not equal</entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <note> |
| <para> |
| <literal><></literal> is the standard SQL notation for <quote>not |
| equal</quote>. <literal>!=</literal> is an alias, which is converted |
| to <literal><></literal> at a very early stage of parsing. |
| Hence, it is not possible to implement <literal>!=</literal> |
| and <literal><></literal> operators that do different things. |
| </para> |
| </note> |
| |
| <para> |
| These comparison operators are available for all built-in data types |
| that have a natural ordering, including numeric, string, and date/time |
| types. In addition, arrays, composite types, and ranges can be compared |
| if their component data types are comparable. |
| </para> |
| |
| <para> |
| It is usually possible to compare values of related data |
| types as well; for example <type>integer</type> <literal>></literal> |
| <type>bigint</type> will work. Some cases of this sort are implemented |
| directly by <quote>cross-type</quote> comparison operators, but if no |
| such operator is available, the parser will coerce the less-general type |
| to the more-general type and apply the latter's comparison operator. |
| </para> |
| |
| <para> |
| As shown above, all comparison operators are binary operators that |
| return values of type <type>boolean</type>. Thus, expressions like |
| <literal>1 < 2 < 3</literal> are not valid (because there is |
| no <literal><</literal> operator to compare a Boolean value with |
| <literal>3</literal>). Use the <literal>BETWEEN</literal> predicates |
| shown below to perform range tests. |
| </para> |
| |
| <para> |
| There are also some comparison predicates, as shown in <xref |
| linkend="functions-comparison-pred-table"/>. These behave much like |
| operators, but have special syntax mandated by the SQL standard. |
| </para> |
| |
| <table id="functions-comparison-pred-table"> |
| <title>Comparison Predicates</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Predicate |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>datatype</replaceable> <literal>BETWEEN</literal> <replaceable>datatype</replaceable> <literal>AND</literal> <replaceable>datatype</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Between (inclusive of the range endpoints). |
| </para> |
| <para> |
| <literal>2 BETWEEN 1 AND 3</literal> |
| <returnvalue>t</returnvalue> |
| </para> |
| <para> |
| <literal>2 BETWEEN 3 AND 1</literal> |
| <returnvalue>f</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>datatype</replaceable> <literal>NOT BETWEEN</literal> <replaceable>datatype</replaceable> <literal>AND</literal> <replaceable>datatype</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Not between (the negation of <literal>BETWEEN</literal>). |
| </para> |
| <para> |
| <literal>2 NOT BETWEEN 1 AND 3</literal> |
| <returnvalue>f</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>datatype</replaceable> <literal>BETWEEN SYMMETRIC</literal> <replaceable>datatype</replaceable> <literal>AND</literal> <replaceable>datatype</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Between, after sorting the two endpoint values. |
| </para> |
| <para> |
| <literal>2 BETWEEN SYMMETRIC 3 AND 1</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>datatype</replaceable> <literal>NOT BETWEEN SYMMETRIC</literal> <replaceable>datatype</replaceable> <literal>AND</literal> <replaceable>datatype</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Not between, after sorting the two endpoint values. |
| </para> |
| <para> |
| <literal>2 NOT BETWEEN SYMMETRIC 3 AND 1</literal> |
| <returnvalue>f</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>datatype</replaceable> <literal>IS DISTINCT FROM</literal> <replaceable>datatype</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Not equal, treating null as a comparable value. |
| </para> |
| <para> |
| <literal>1 IS DISTINCT FROM NULL</literal> |
| <returnvalue>t</returnvalue> (rather than <literal>NULL</literal>) |
| </para> |
| <para> |
| <literal>NULL IS DISTINCT FROM NULL</literal> |
| <returnvalue>f</returnvalue> (rather than <literal>NULL</literal>) |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>datatype</replaceable> <literal>IS NOT DISTINCT FROM</literal> <replaceable>datatype</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Equal, treating null as a comparable value. |
| </para> |
| <para> |
| <literal>1 IS NOT DISTINCT FROM NULL</literal> |
| <returnvalue>f</returnvalue> (rather than <literal>NULL</literal>) |
| </para> |
| <para> |
| <literal>NULL IS NOT DISTINCT FROM NULL</literal> |
| <returnvalue>t</returnvalue> (rather than <literal>NULL</literal>) |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>datatype</replaceable> <literal>IS NULL</literal> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Test whether value is null. |
| </para> |
| <para> |
| <literal>1.5 IS NULL</literal> |
| <returnvalue>f</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>datatype</replaceable> <literal>IS NOT NULL</literal> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Test whether value is not null. |
| </para> |
| <para> |
| <literal>'null' IS NOT NULL</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>datatype</replaceable> <literal>ISNULL</literal> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Test whether value is null (nonstandard syntax). |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>datatype</replaceable> <literal>NOTNULL</literal> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Test whether value is not null (nonstandard syntax). |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>boolean</type> <literal>IS TRUE</literal> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Test whether boolean expression yields true. |
| </para> |
| <para> |
| <literal>true IS TRUE</literal> |
| <returnvalue>t</returnvalue> |
| </para> |
| <para> |
| <literal>NULL::boolean IS TRUE</literal> |
| <returnvalue>f</returnvalue> (rather than <literal>NULL</literal>) |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>boolean</type> <literal>IS NOT TRUE</literal> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Test whether boolean expression yields false or unknown. |
| </para> |
| <para> |
| <literal>true IS NOT TRUE</literal> |
| <returnvalue>f</returnvalue> |
| </para> |
| <para> |
| <literal>NULL::boolean IS NOT TRUE</literal> |
| <returnvalue>t</returnvalue> (rather than <literal>NULL</literal>) |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>boolean</type> <literal>IS FALSE</literal> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Test whether boolean expression yields false. |
| </para> |
| <para> |
| <literal>true IS FALSE</literal> |
| <returnvalue>f</returnvalue> |
| </para> |
| <para> |
| <literal>NULL::boolean IS FALSE</literal> |
| <returnvalue>f</returnvalue> (rather than <literal>NULL</literal>) |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>boolean</type> <literal>IS NOT FALSE</literal> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Test whether boolean expression yields true or unknown. |
| </para> |
| <para> |
| <literal>true IS NOT FALSE</literal> |
| <returnvalue>t</returnvalue> |
| </para> |
| <para> |
| <literal>NULL::boolean IS NOT FALSE</literal> |
| <returnvalue>t</returnvalue> (rather than <literal>NULL</literal>) |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>boolean</type> <literal>IS UNKNOWN</literal> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Test whether boolean expression yields unknown. |
| </para> |
| <para> |
| <literal>true IS UNKNOWN</literal> |
| <returnvalue>f</returnvalue> |
| </para> |
| <para> |
| <literal>NULL::boolean IS UNKNOWN</literal> |
| <returnvalue>t</returnvalue> (rather than <literal>NULL</literal>) |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>boolean</type> <literal>IS NOT UNKNOWN</literal> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Test whether boolean expression yields true or false. |
| </para> |
| <para> |
| <literal>true IS NOT UNKNOWN</literal> |
| <returnvalue>t</returnvalue> |
| </para> |
| <para> |
| <literal>NULL::boolean IS NOT UNKNOWN</literal> |
| <returnvalue>f</returnvalue> (rather than <literal>NULL</literal>) |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| <indexterm> |
| <primary>BETWEEN</primary> |
| </indexterm> |
| <indexterm> |
| <primary>BETWEEN SYMMETRIC</primary> |
| </indexterm> |
| The <token>BETWEEN</token> predicate simplifies range tests: |
| <synopsis> |
| <replaceable>a</replaceable> BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable> |
| </synopsis> |
| is equivalent to |
| <synopsis> |
| <replaceable>a</replaceable> >= <replaceable>x</replaceable> AND <replaceable>a</replaceable> <= <replaceable>y</replaceable> |
| </synopsis> |
| Notice that <token>BETWEEN</token> treats the endpoint values as included |
| in the range. |
| <literal>BETWEEN SYMMETRIC</literal> is like <literal>BETWEEN</literal> |
| except there is no requirement that the argument to the left of |
| <literal>AND</literal> be less than or equal to the argument on the right. |
| If it is not, those two arguments are automatically swapped, so that |
| a nonempty range is always implied. |
| </para> |
| |
| <para> |
| The various variants of <literal>BETWEEN</literal> are implemented in |
| terms of the ordinary comparison operators, and therefore will work for |
| any data type(s) that can be compared. |
| </para> |
| |
| <note> |
| <para> |
| The use of <literal>AND</literal> in the <literal>BETWEEN</literal> |
| syntax creates an ambiguity with the use of <literal>AND</literal> as a |
| logical operator. To resolve this, only a limited set of expression |
| types are allowed as the second argument of a <literal>BETWEEN</literal> |
| clause. If you need to write a more complex sub-expression |
| in <literal>BETWEEN</literal>, write parentheses around the |
| sub-expression. |
| </para> |
| </note> |
| |
| <para> |
| <indexterm> |
| <primary>IS DISTINCT FROM</primary> |
| </indexterm> |
| <indexterm> |
| <primary>IS NOT DISTINCT FROM</primary> |
| </indexterm> |
| Ordinary comparison operators yield null (signifying <quote>unknown</quote>), |
| not true or false, when either input is null. For example, |
| <literal>7 = NULL</literal> yields null, as does <literal>7 <> NULL</literal>. When |
| this behavior is not suitable, use the |
| <literal>IS <optional> NOT </optional> DISTINCT FROM</literal> predicates: |
| <synopsis> |
| <replaceable>a</replaceable> IS DISTINCT FROM <replaceable>b</replaceable> |
| <replaceable>a</replaceable> IS NOT DISTINCT FROM <replaceable>b</replaceable> |
| </synopsis> |
| For non-null inputs, <literal>IS DISTINCT FROM</literal> is |
| the same as the <literal><></literal> operator. However, if both |
| inputs are null it returns false, and if only one input is |
| null it returns true. Similarly, <literal>IS NOT DISTINCT |
| FROM</literal> is identical to <literal>=</literal> for non-null |
| inputs, but it returns true when both inputs are null, and false when only |
| one input is null. Thus, these predicates effectively act as though null |
| were a normal data value, rather than <quote>unknown</quote>. |
| </para> |
| |
| <para> |
| <indexterm> |
| <primary>IS NULL</primary> |
| </indexterm> |
| <indexterm> |
| <primary>IS NOT NULL</primary> |
| </indexterm> |
| <indexterm> |
| <primary>ISNULL</primary> |
| </indexterm> |
| <indexterm> |
| <primary>NOTNULL</primary> |
| </indexterm> |
| To check whether a value is or is not null, use the predicates: |
| <synopsis> |
| <replaceable>expression</replaceable> IS NULL |
| <replaceable>expression</replaceable> IS NOT NULL |
| </synopsis> |
| or the equivalent, but nonstandard, predicates: |
| <synopsis> |
| <replaceable>expression</replaceable> ISNULL |
| <replaceable>expression</replaceable> NOTNULL |
| </synopsis> |
| <indexterm><primary>null value</primary><secondary>comparing</secondary></indexterm> |
| </para> |
| |
| <para> |
| Do <emphasis>not</emphasis> write |
| <literal><replaceable>expression</replaceable> = NULL</literal> |
| because <literal>NULL</literal> is not <quote>equal to</quote> |
| <literal>NULL</literal>. (The null value represents an unknown value, |
| and it is not known whether two unknown values are equal.) |
| </para> |
| |
| <tip> |
| <para> |
| Some applications might expect that |
| <literal><replaceable>expression</replaceable> = NULL</literal> |
| returns true if <replaceable>expression</replaceable> evaluates to |
| the null value. It is highly recommended that these applications |
| be modified to comply with the SQL standard. However, if that |
| cannot be done the <xref linkend="guc-transform-null-equals"/> |
| configuration variable is available. If it is enabled, |
| <productname>PostgreSQL</productname> will convert <literal>x = |
| NULL</literal> clauses to <literal>x IS NULL</literal>. |
| </para> |
| </tip> |
| |
| <para> |
| If the <replaceable>expression</replaceable> is row-valued, then |
| <literal>IS NULL</literal> is true when the row expression itself is null |
| or when all the row's fields are null, while |
| <literal>IS NOT NULL</literal> is true when the row expression itself is non-null |
| and all the row's fields are non-null. Because of this behavior, |
| <literal>IS NULL</literal> and <literal>IS NOT NULL</literal> do not always return |
| inverse results for row-valued expressions; in particular, a row-valued |
| expression that contains both null and non-null fields will return false |
| for both tests. In some cases, it may be preferable to |
| write <replaceable>row</replaceable> <literal>IS DISTINCT FROM NULL</literal> |
| or <replaceable>row</replaceable> <literal>IS NOT DISTINCT FROM NULL</literal>, |
| which will simply check whether the overall row value is null without any |
| additional tests on the row fields. |
| </para> |
| |
| <para> |
| <indexterm> |
| <primary>IS TRUE</primary> |
| </indexterm> |
| <indexterm> |
| <primary>IS NOT TRUE</primary> |
| </indexterm> |
| <indexterm> |
| <primary>IS FALSE</primary> |
| </indexterm> |
| <indexterm> |
| <primary>IS NOT FALSE</primary> |
| </indexterm> |
| <indexterm> |
| <primary>IS UNKNOWN</primary> |
| </indexterm> |
| <indexterm> |
| <primary>IS NOT UNKNOWN</primary> |
| </indexterm> |
| Boolean values can also be tested using the predicates |
| <synopsis> |
| <replaceable>boolean_expression</replaceable> IS TRUE |
| <replaceable>boolean_expression</replaceable> IS NOT TRUE |
| <replaceable>boolean_expression</replaceable> IS FALSE |
| <replaceable>boolean_expression</replaceable> IS NOT FALSE |
| <replaceable>boolean_expression</replaceable> IS UNKNOWN |
| <replaceable>boolean_expression</replaceable> IS NOT UNKNOWN |
| </synopsis> |
| These will always return true or false, never a null value, even when the |
| operand is null. |
| A null input is treated as the logical value <quote>unknown</quote>. |
| Notice that <literal>IS UNKNOWN</literal> and <literal>IS NOT UNKNOWN</literal> are |
| effectively the same as <literal>IS NULL</literal> and |
| <literal>IS NOT NULL</literal>, respectively, except that the input |
| expression must be of Boolean type. |
| </para> |
| |
| <para> |
| Some comparison-related functions are also available, as shown in <xref |
| linkend="functions-comparison-func-table"/>. |
| </para> |
| |
| <table id="functions-comparison-func-table"> |
| <title>Comparison Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>num_nonnulls</primary> |
| </indexterm> |
| <function>num_nonnulls</function> ( <literal>VARIADIC</literal> <type>"any"</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns the number of non-null arguments. |
| </para> |
| <para> |
| <literal>num_nonnulls(1, NULL, 2)</literal> |
| <returnvalue>2</returnvalue> |
| </para></entry> |
| </row> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>num_nulls</primary> |
| </indexterm> |
| <function>num_nulls</function> ( <literal>VARIADIC</literal> <type>"any"</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns the number of null arguments. |
| </para> |
| <para> |
| <literal>num_nulls(1, NULL, 2)</literal> |
| <returnvalue>1</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| </sect1> |
| |
| <sect1 id="functions-math"> |
| <title>Mathematical Functions and Operators</title> |
| |
| <para> |
| Mathematical operators are provided for many |
| <productname>PostgreSQL</productname> types. For types without |
| standard mathematical conventions |
| (e.g., date/time types) we |
| describe the actual behavior in subsequent sections. |
| </para> |
| |
| <para> |
| <xref linkend="functions-math-op-table"/> shows the mathematical |
| operators that are available for the standard numeric types. |
| Unless otherwise noted, operators shown as |
| accepting <replaceable>numeric_type</replaceable> are available for all |
| the types <type>smallint</type>, <type>integer</type>, |
| <type>bigint</type>, <type>numeric</type>, <type>real</type>, |
| and <type>double precision</type>. |
| Operators shown as accepting <replaceable>integral_type</replaceable> |
| are available for the types <type>smallint</type>, <type>integer</type>, |
| and <type>bigint</type>. |
| Except where noted, each form of an operator returns the same data type |
| as its argument(s). Calls involving multiple argument data types, such |
| as <type>integer</type> <literal>+</literal> <type>numeric</type>, |
| are resolved by using the type appearing later in these lists. |
| </para> |
| |
| <table id="functions-math-op-table"> |
| <title>Mathematical Operators</title> |
| |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Operator |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>numeric_type</replaceable> <literal>+</literal> <replaceable>numeric_type</replaceable> |
| <returnvalue><replaceable>numeric_type</replaceable></returnvalue> |
| </para> |
| <para> |
| Addition |
| </para> |
| <para> |
| <literal>2 + 3</literal> |
| <returnvalue>5</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <literal>+</literal> <replaceable>numeric_type</replaceable> |
| <returnvalue><replaceable>numeric_type</replaceable></returnvalue> |
| </para> |
| <para> |
| Unary plus (no operation) |
| </para> |
| <para> |
| <literal>+ 3.5</literal> |
| <returnvalue>3.5</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>numeric_type</replaceable> <literal>-</literal> <replaceable>numeric_type</replaceable> |
| <returnvalue><replaceable>numeric_type</replaceable></returnvalue> |
| </para> |
| <para> |
| Subtraction |
| </para> |
| <para> |
| <literal>2 - 3</literal> |
| <returnvalue>-1</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <literal>-</literal> <replaceable>numeric_type</replaceable> |
| <returnvalue><replaceable>numeric_type</replaceable></returnvalue> |
| </para> |
| <para> |
| Negation |
| </para> |
| <para> |
| <literal>- (-4)</literal> |
| <returnvalue>4</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>numeric_type</replaceable> <literal>*</literal> <replaceable>numeric_type</replaceable> |
| <returnvalue><replaceable>numeric_type</replaceable></returnvalue> |
| </para> |
| <para> |
| Multiplication |
| </para> |
| <para> |
| <literal>2 * 3</literal> |
| <returnvalue>6</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>numeric_type</replaceable> <literal>/</literal> <replaceable>numeric_type</replaceable> |
| <returnvalue><replaceable>numeric_type</replaceable></returnvalue> |
| </para> |
| <para> |
| Division (for integral types, division truncates the result towards |
| zero) |
| </para> |
| <para> |
| <literal>5.0 / 2</literal> |
| <returnvalue>2.5000000000000000</returnvalue> |
| </para> |
| <para> |
| <literal>5 / 2</literal> |
| <returnvalue>2</returnvalue> |
| </para> |
| <para> |
| <literal>(-5) / 2</literal> |
| <returnvalue>-2</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>numeric_type</replaceable> <literal>%</literal> <replaceable>numeric_type</replaceable> |
| <returnvalue><replaceable>numeric_type</replaceable></returnvalue> |
| </para> |
| <para> |
| Modulo (remainder); available for <type>smallint</type>, |
| <type>integer</type>, <type>bigint</type>, and <type>numeric</type> |
| </para> |
| <para> |
| <literal>5 % 4</literal> |
| <returnvalue>1</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>numeric</type> <literal>^</literal> <type>numeric</type> |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <type>double precision</type> <literal>^</literal> <type>double precision</type> |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Exponentiation |
| </para> |
| <para> |
| <literal>2 ^ 3</literal> |
| <returnvalue>8</returnvalue> |
| </para> |
| <para> |
| Unlike typical mathematical practice, multiple uses of |
| <literal>^</literal> will associate left to right by default: |
| </para> |
| <para> |
| <literal>2 ^ 3 ^ 3</literal> |
| <returnvalue>512</returnvalue> |
| </para> |
| <para> |
| <literal>2 ^ (3 ^ 3)</literal> |
| <returnvalue>134217728</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <literal>|/</literal> <type>double precision</type> |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Square root |
| </para> |
| <para> |
| <literal>|/ 25.0</literal> |
| <returnvalue>5</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <literal>||/</literal> <type>double precision</type> |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Cube root |
| </para> |
| <para> |
| <literal>||/ 64.0</literal> |
| <returnvalue>4</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <literal>@</literal> <replaceable>numeric_type</replaceable> |
| <returnvalue><replaceable>numeric_type</replaceable></returnvalue> |
| </para> |
| <para> |
| Absolute value |
| </para> |
| <para> |
| <literal>@ -5.0</literal> |
| <returnvalue>5.0</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>integral_type</replaceable> <literal>&</literal> <replaceable>integral_type</replaceable> |
| <returnvalue><replaceable>integral_type</replaceable></returnvalue> |
| </para> |
| <para> |
| Bitwise AND |
| </para> |
| <para> |
| <literal>91 & 15</literal> |
| <returnvalue>11</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>integral_type</replaceable> <literal>|</literal> <replaceable>integral_type</replaceable> |
| <returnvalue><replaceable>integral_type</replaceable></returnvalue> |
| </para> |
| <para> |
| Bitwise OR |
| </para> |
| <para> |
| <literal>32 | 3</literal> |
| <returnvalue>35</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>integral_type</replaceable> <literal>#</literal> <replaceable>integral_type</replaceable> |
| <returnvalue><replaceable>integral_type</replaceable></returnvalue> |
| </para> |
| <para> |
| Bitwise exclusive OR |
| </para> |
| <para> |
| <literal>17 # 5</literal> |
| <returnvalue>20</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <literal>~</literal> <replaceable>integral_type</replaceable> |
| <returnvalue><replaceable>integral_type</replaceable></returnvalue> |
| </para> |
| <para> |
| Bitwise NOT |
| </para> |
| <para> |
| <literal>~1</literal> |
| <returnvalue>-2</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>integral_type</replaceable> <literal><<</literal> <type>integer</type> |
| <returnvalue><replaceable>integral_type</replaceable></returnvalue> |
| </para> |
| <para> |
| Bitwise shift left |
| </para> |
| <para> |
| <literal>1 << 4</literal> |
| <returnvalue>16</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>integral_type</replaceable> <literal>>></literal> <type>integer</type> |
| <returnvalue><replaceable>integral_type</replaceable></returnvalue> |
| </para> |
| <para> |
| Bitwise shift right |
| </para> |
| <para> |
| <literal>8 >> 2</literal> |
| <returnvalue>2</returnvalue> |
| </para></entry> |
| </row> |
| |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| <xref linkend="functions-math-func-table"/> shows the available |
| mathematical functions. |
| Many of these functions are provided in multiple forms with different |
| argument types. |
| Except where noted, any given form of a function returns the same |
| data type as its argument(s); cross-type cases are resolved in the |
| same way as explained above for operators. |
| The functions working with <type>double precision</type> data are mostly |
| implemented on top of the host system's C library; accuracy and behavior in |
| boundary cases can therefore vary depending on the host system. |
| </para> |
| |
| <table id="functions-math-func-table"> |
| <title>Mathematical Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>abs</primary> |
| </indexterm> |
| <function>abs</function> ( <replaceable>numeric_type</replaceable> ) |
| <returnvalue><replaceable>numeric_type</replaceable></returnvalue> |
| </para> |
| <para> |
| Absolute value |
| </para> |
| <para> |
| <literal>abs(-17.4)</literal> |
| <returnvalue>17.4</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>cbrt</primary> |
| </indexterm> |
| <function>cbrt</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Cube root |
| </para> |
| <para> |
| <literal>cbrt(64.0)</literal> |
| <returnvalue>4</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>ceil</primary> |
| </indexterm> |
| <function>ceil</function> ( <type>numeric</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>ceil</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Nearest integer greater than or equal to argument |
| </para> |
| <para> |
| <literal>ceil(42.2)</literal> |
| <returnvalue>43</returnvalue> |
| </para> |
| <para> |
| <literal>ceil(-42.8)</literal> |
| <returnvalue>-42</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>ceiling</primary> |
| </indexterm> |
| <function>ceiling</function> ( <type>numeric</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>ceiling</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Nearest integer greater than or equal to argument (same |
| as <function>ceil</function>) |
| </para> |
| <para> |
| <literal>ceiling(95.3)</literal> |
| <returnvalue>96</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>degrees</primary> |
| </indexterm> |
| <function>degrees</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Converts radians to degrees |
| </para> |
| <para> |
| <literal>degrees(0.5)</literal> |
| <returnvalue>28.64788975654116</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>div</primary> |
| </indexterm> |
| <function>div</function> ( <parameter>y</parameter> <type>numeric</type>, |
| <parameter>x</parameter> <type>numeric</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para> |
| Integer quotient of <parameter>y</parameter>/<parameter>x</parameter> |
| (truncates towards zero) |
| </para> |
| <para> |
| <literal>div(9, 4)</literal> |
| <returnvalue>2</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>exp</primary> |
| </indexterm> |
| <function>exp</function> ( <type>numeric</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>exp</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Exponential (<literal>e</literal> raised to the given power) |
| </para> |
| <para> |
| <literal>exp(1.0)</literal> |
| <returnvalue>2.7182818284590452</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm id="function-factorial"> |
| <primary>factorial</primary> |
| </indexterm> |
| <function>factorial</function> ( <type>bigint</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para> |
| Factorial |
| </para> |
| <para> |
| <literal>factorial(5)</literal> |
| <returnvalue>120</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>floor</primary> |
| </indexterm> |
| <function>floor</function> ( <type>numeric</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>floor</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Nearest integer less than or equal to argument |
| </para> |
| <para> |
| <literal>floor(42.8)</literal> |
| <returnvalue>42</returnvalue> |
| </para> |
| <para> |
| <literal>floor(-42.8)</literal> |
| <returnvalue>-43</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>gcd</primary> |
| </indexterm> |
| <function>gcd</function> ( <replaceable>numeric_type</replaceable>, <replaceable>numeric_type</replaceable> ) |
| <returnvalue><replaceable>numeric_type</replaceable></returnvalue> |
| </para> |
| <para> |
| Greatest common divisor (the largest positive number that divides both |
| inputs with no remainder); returns <literal>0</literal> if both inputs |
| are zero; available for <type>integer</type>, <type>bigint</type>, |
| and <type>numeric</type> |
| </para> |
| <para> |
| <literal>gcd(1071, 462)</literal> |
| <returnvalue>21</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>lcm</primary> |
| </indexterm> |
| <function>lcm</function> ( <replaceable>numeric_type</replaceable>, <replaceable>numeric_type</replaceable> ) |
| <returnvalue><replaceable>numeric_type</replaceable></returnvalue> |
| </para> |
| <para> |
| Least common multiple (the smallest strictly positive number that is |
| an integral multiple of both inputs); returns <literal>0</literal> if |
| either input is zero; available for <type>integer</type>, |
| <type>bigint</type>, and <type>numeric</type> |
| </para> |
| <para> |
| <literal>lcm(1071, 462)</literal> |
| <returnvalue>23562</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>ln</primary> |
| </indexterm> |
| <function>ln</function> ( <type>numeric</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>ln</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Natural logarithm |
| </para> |
| <para> |
| <literal>ln(2.0)</literal> |
| <returnvalue>0.6931471805599453</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>log</primary> |
| </indexterm> |
| <function>log</function> ( <type>numeric</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>log</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Base 10 logarithm |
| </para> |
| <para> |
| <literal>log(100)</literal> |
| <returnvalue>2</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>log10</primary> |
| </indexterm> |
| <function>log10</function> ( <type>numeric</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>log10</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Base 10 logarithm (same as <function>log</function>) |
| </para> |
| <para> |
| <literal>log10(1000)</literal> |
| <returnvalue>3</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>log</function> ( <parameter>b</parameter> <type>numeric</type>, |
| <parameter>x</parameter> <type>numeric</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para> |
| Logarithm of <parameter>x</parameter> to base <parameter>b</parameter> |
| </para> |
| <para> |
| <literal>log(2.0, 64.0)</literal> |
| <returnvalue>6.0000000000000000</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>min_scale</primary> |
| </indexterm> |
| <function>min_scale</function> ( <type>numeric</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Minimum scale (number of fractional decimal digits) needed |
| to represent the supplied value precisely |
| </para> |
| <para> |
| <literal>min_scale(8.4100)</literal> |
| <returnvalue>2</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>mod</primary> |
| </indexterm> |
| <function>mod</function> ( <parameter>y</parameter> <replaceable>numeric_type</replaceable>, |
| <parameter>x</parameter> <replaceable>numeric_type</replaceable> ) |
| <returnvalue><replaceable>numeric_type</replaceable></returnvalue> |
| </para> |
| <para> |
| Remainder of <parameter>y</parameter>/<parameter>x</parameter>; |
| available for <type>smallint</type>, <type>integer</type>, |
| <type>bigint</type>, and <type>numeric</type> |
| </para> |
| <para> |
| <literal>mod(9, 4)</literal> |
| <returnvalue>1</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pi</primary> |
| </indexterm> |
| <function>pi</function> ( ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Approximate value of <phrase role="symbol_font">π</phrase> |
| </para> |
| <para> |
| <literal>pi()</literal> |
| <returnvalue>3.141592653589793</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>power</primary> |
| </indexterm> |
| <function>power</function> ( <parameter>a</parameter> <type>numeric</type>, |
| <parameter>b</parameter> <type>numeric</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>power</function> ( <parameter>a</parameter> <type>double precision</type>, |
| <parameter>b</parameter> <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| <parameter>a</parameter> raised to the power of <parameter>b</parameter> |
| </para> |
| <para> |
| <literal>power(9, 3)</literal> |
| <returnvalue>729</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>radians</primary> |
| </indexterm> |
| <function>radians</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Converts degrees to radians |
| </para> |
| <para> |
| <literal>radians(45.0)</literal> |
| <returnvalue>0.7853981633974483</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>round</primary> |
| </indexterm> |
| <function>round</function> ( <type>numeric</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>round</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Rounds to nearest integer. For <type>numeric</type>, ties are |
| broken by rounding away from zero. For <type>double precision</type>, |
| the tie-breaking behavior is platform dependent, but |
| <quote>round to nearest even</quote> is the most common rule. |
| </para> |
| <para> |
| <literal>round(42.4)</literal> |
| <returnvalue>42</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>round</function> ( <parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>integer</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para> |
| Rounds <parameter>v</parameter> to <parameter>s</parameter> decimal |
| places. Ties are broken by rounding away from zero. |
| </para> |
| <para> |
| <literal>round(42.4382, 2)</literal> |
| <returnvalue>42.44</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>scale</primary> |
| </indexterm> |
| <function>scale</function> ( <type>numeric</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Scale of the argument (the number of decimal digits in the fractional part) |
| </para> |
| <para> |
| <literal>scale(8.4100)</literal> |
| <returnvalue>4</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>sign</primary> |
| </indexterm> |
| <function>sign</function> ( <type>numeric</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>sign</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Sign of the argument (-1, 0, or +1) |
| </para> |
| <para> |
| <literal>sign(-8.4)</literal> |
| <returnvalue>-1</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>sqrt</primary> |
| </indexterm> |
| <function>sqrt</function> ( <type>numeric</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>sqrt</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Square root |
| </para> |
| <para> |
| <literal>sqrt(2)</literal> |
| <returnvalue>1.4142135623730951</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>trim_scale</primary> |
| </indexterm> |
| <function>trim_scale</function> ( <type>numeric</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para> |
| Reduces the value's scale (number of fractional decimal digits) by |
| removing trailing zeroes |
| </para> |
| <para> |
| <literal>trim_scale(8.4100)</literal> |
| <returnvalue>8.41</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>trunc</primary> |
| </indexterm> |
| <function>trunc</function> ( <type>numeric</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>trunc</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Truncates to integer (towards zero) |
| </para> |
| <para> |
| <literal>trunc(42.8)</literal> |
| <returnvalue>42</returnvalue> |
| </para> |
| <para> |
| <literal>trunc(-42.8)</literal> |
| <returnvalue>-42</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>trunc</function> ( <parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>integer</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para> |
| Truncates <parameter>v</parameter> to <parameter>s</parameter> |
| decimal places |
| </para> |
| <para> |
| <literal>trunc(42.4382, 2)</literal> |
| <returnvalue>42.43</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>width_bucket</primary> |
| </indexterm> |
| <function>width_bucket</function> ( <parameter>operand</parameter> <type>numeric</type>, <parameter>low</parameter> <type>numeric</type>, <parameter>high</parameter> <type>numeric</type>, <parameter>count</parameter> <type>integer</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>width_bucket</function> ( <parameter>operand</parameter> <type>double precision</type>, <parameter>low</parameter> <type>double precision</type>, <parameter>high</parameter> <type>double precision</type>, <parameter>count</parameter> <type>integer</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns the number of the bucket in |
| which <parameter>operand</parameter> falls in a histogram |
| having <parameter>count</parameter> equal-width buckets spanning the |
| range <parameter>low</parameter> to <parameter>high</parameter>. |
| Returns <literal>0</literal> |
| or <literal><parameter>count</parameter>+1</literal> for an input |
| outside that range. |
| </para> |
| <para> |
| <literal>width_bucket(5.35, 0.024, 10.06, 5)</literal> |
| <returnvalue>3</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>width_bucket</function> ( <parameter>operand</parameter> <type>anycompatible</type>, <parameter>thresholds</parameter> <type>anycompatiblearray</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns the number of the bucket in |
| which <parameter>operand</parameter> falls given an array listing the |
| lower bounds of the buckets. Returns <literal>0</literal> for an |
| input less than the first lower |
| bound. <parameter>operand</parameter> and the array elements can be |
| of any type having standard comparison operators. |
| The <parameter>thresholds</parameter> array <emphasis>must be |
| sorted</emphasis>, smallest first, or unexpected results will be |
| obtained. |
| </para> |
| <para> |
| <literal>width_bucket(now(), array['yesterday', 'today', 'tomorrow']::timestamptz[])</literal> |
| <returnvalue>2</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| <xref linkend="functions-math-random-table"/> shows functions for |
| generating random numbers. |
| </para> |
| |
| <table id="functions-math-random-table"> |
| <title>Random Functions</title> |
| |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>random</primary> |
| </indexterm> |
| <function>random</function> ( ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Returns a random value in the range 0.0 <= x < 1.0 |
| </para> |
| <para> |
| <literal>random()</literal> |
| <returnvalue>0.897124072839091</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>setseed</primary> |
| </indexterm> |
| <function>setseed</function> ( <type>double precision</type> ) |
| <returnvalue>void</returnvalue> |
| </para> |
| <para> |
| Sets the seed for subsequent <literal>random()</literal> calls; |
| argument must be between -1.0 and 1.0, inclusive |
| </para> |
| <para> |
| <literal>setseed(0.12345)</literal> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| The <function>random()</function> function uses a simple linear |
| congruential algorithm. It is fast but not suitable for cryptographic |
| applications; see the <xref linkend="pgcrypto"/> module for a more |
| secure alternative. |
| If <function>setseed()</function> is called, the series of results of |
| subsequent <function>random()</function> calls in the current session |
| can be repeated by re-issuing <function>setseed()</function> with the same |
| argument. |
| </para> |
| |
| <para> |
| <xref linkend="functions-math-trig-table"/> shows the |
| available trigonometric functions. Each of these functions comes in |
| two variants, one that measures angles in radians and one that |
| measures angles in degrees. |
| </para> |
| |
| <table id="functions-math-trig-table"> |
| <title>Trigonometric Functions</title> |
| |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>acos</primary> |
| </indexterm> |
| <function>acos</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Inverse cosine, result in radians |
| </para> |
| <para> |
| <literal>acos(1)</literal> |
| <returnvalue>0</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>acosd</primary> |
| </indexterm> |
| <function>acosd</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Inverse cosine, result in degrees |
| </para> |
| <para> |
| <literal>acosd(0.5)</literal> |
| <returnvalue>60</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>asin</primary> |
| </indexterm> |
| <function>asin</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Inverse sine, result in radians |
| </para> |
| <para> |
| <literal>asin(1)</literal> |
| <returnvalue>1.5707963267948966</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>asind</primary> |
| </indexterm> |
| <function>asind</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Inverse sine, result in degrees |
| </para> |
| <para> |
| <literal>asind(0.5)</literal> |
| <returnvalue>30</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>atan</primary> |
| </indexterm> |
| <function>atan</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Inverse tangent, result in radians |
| </para> |
| <para> |
| <literal>atan(1)</literal> |
| <returnvalue>0.7853981633974483</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>atand</primary> |
| </indexterm> |
| <function>atand</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Inverse tangent, result in degrees |
| </para> |
| <para> |
| <literal>atand(1)</literal> |
| <returnvalue>45</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>atan2</primary> |
| </indexterm> |
| <function>atan2</function> ( <parameter>y</parameter> <type>double precision</type>, |
| <parameter>x</parameter> <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Inverse tangent of |
| <parameter>y</parameter>/<parameter>x</parameter>, |
| result in radians |
| </para> |
| <para> |
| <literal>atan2(1, 0)</literal> |
| <returnvalue>1.5707963267948966</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>atan2d</primary> |
| </indexterm> |
| <function>atan2d</function> ( <parameter>y</parameter> <type>double precision</type>, |
| <parameter>x</parameter> <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Inverse tangent of |
| <parameter>y</parameter>/<parameter>x</parameter>, |
| result in degrees |
| </para> |
| <para> |
| <literal>atan2d(1, 0)</literal> |
| <returnvalue>90</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>cos</primary> |
| </indexterm> |
| <function>cos</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Cosine, argument in radians |
| </para> |
| <para> |
| <literal>cos(0)</literal> |
| <returnvalue>1</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>cosd</primary> |
| </indexterm> |
| <function>cosd</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Cosine, argument in degrees |
| </para> |
| <para> |
| <literal>cosd(60)</literal> |
| <returnvalue>0.5</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>cot</primary> |
| </indexterm> |
| <function>cot</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Cotangent, argument in radians |
| </para> |
| <para> |
| <literal>cot(0.5)</literal> |
| <returnvalue>1.830487721712452</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>cotd</primary> |
| </indexterm> |
| <function>cotd</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Cotangent, argument in degrees |
| </para> |
| <para> |
| <literal>cotd(45)</literal> |
| <returnvalue>1</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>sin</primary> |
| </indexterm> |
| <function>sin</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Sine, argument in radians |
| </para> |
| <para> |
| <literal>sin(1)</literal> |
| <returnvalue>0.8414709848078965</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>sind</primary> |
| </indexterm> |
| <function>sind</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Sine, argument in degrees |
| </para> |
| <para> |
| <literal>sind(30)</literal> |
| <returnvalue>0.5</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>tan</primary> |
| </indexterm> |
| <function>tan</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Tangent, argument in radians |
| </para> |
| <para> |
| <literal>tan(1)</literal> |
| <returnvalue>1.5574077246549023</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>tand</primary> |
| </indexterm> |
| <function>tand</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Tangent, argument in degrees |
| </para> |
| <para> |
| <literal>tand(45)</literal> |
| <returnvalue>1</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <note> |
| <para> |
| Another way to work with angles measured in degrees is to use the unit |
| transformation functions <literal><function>radians()</function></literal> |
| and <literal><function>degrees()</function></literal> shown earlier. |
| However, using the degree-based trigonometric functions is preferred, |
| as that way avoids round-off error for special cases such |
| as <literal>sind(30)</literal>. |
| </para> |
| </note> |
| |
| <para> |
| <xref linkend="functions-math-hyp-table"/> shows the |
| available hyperbolic functions. |
| </para> |
| |
| <table id="functions-math-hyp-table"> |
| <title>Hyperbolic Functions</title> |
| |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>sinh</primary> |
| </indexterm> |
| <function>sinh</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Hyperbolic sine |
| </para> |
| <para> |
| <literal>sinh(1)</literal> |
| <returnvalue>1.1752011936438014</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>cosh</primary> |
| </indexterm> |
| <function>cosh</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Hyperbolic cosine |
| </para> |
| <para> |
| <literal>cosh(0)</literal> |
| <returnvalue>1</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>tanh</primary> |
| </indexterm> |
| <function>tanh</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Hyperbolic tangent |
| </para> |
| <para> |
| <literal>tanh(1)</literal> |
| <returnvalue>0.7615941559557649</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>asinh</primary> |
| </indexterm> |
| <function>asinh</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Inverse hyperbolic sine |
| </para> |
| <para> |
| <literal>asinh(1)</literal> |
| <returnvalue>0.881373587019543</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>acosh</primary> |
| </indexterm> |
| <function>acosh</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Inverse hyperbolic cosine |
| </para> |
| <para> |
| <literal>acosh(1)</literal> |
| <returnvalue>0</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>atanh</primary> |
| </indexterm> |
| <function>atanh</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Inverse hyperbolic tangent |
| </para> |
| <para> |
| <literal>atanh(0.5)</literal> |
| <returnvalue>0.5493061443340548</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| </sect1> |
| |
| |
| <sect1 id="functions-string"> |
| <title>String Functions and Operators</title> |
| |
| <para> |
| This section describes functions and operators for examining and |
| manipulating string values. Strings in this context include values |
| of the types <type>character</type>, <type>character varying</type>, |
| and <type>text</type>. Except where noted, these functions and operators |
| are declared to accept and return type <type>text</type>. They will |
| interchangeably accept <type>character varying</type> arguments. |
| Values of type <type>character</type> will be converted |
| to <type>text</type> before the function or operator is applied, resulting |
| in stripping any trailing spaces in the <type>character</type> value. |
| </para> |
| |
| <para> |
| <acronym>SQL</acronym> defines some string functions that use |
| key words, rather than commas, to separate |
| arguments. Details are in |
| <xref linkend="functions-string-sql"/>. |
| <productname>PostgreSQL</productname> also provides versions of these functions |
| that use the regular function invocation syntax |
| (see <xref linkend="functions-string-other"/>). |
| </para> |
| |
| <note> |
| <para> |
| The string concatenation operator (<literal>||</literal>) will accept |
| non-string input, so long as at least one input is of string type, as shown |
| in <xref linkend="functions-string-sql"/>. For other cases, inserting an |
| explicit coercion to <type>text</type> can be used to have non-string input |
| accepted. |
| </para> |
| </note> |
| |
| <table id="functions-string-sql"> |
| <title><acronym>SQL</acronym> String Functions and Operators</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function/Operator |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>character string</primary> |
| <secondary>concatenation</secondary> |
| </indexterm> |
| <type>text</type> <literal>||</literal> <type>text</type> |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Concatenates the two strings. |
| </para> |
| <para> |
| <literal>'Post' || 'greSQL'</literal> |
| <returnvalue>PostgreSQL</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>text</type> <literal>||</literal> <type>anynonarray</type> |
| <returnvalue>text</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <type>anynonarray</type> <literal>||</literal> <type>text</type> |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Converts the non-string input to text, then concatenates the two |
| strings. (The non-string input cannot be of an array type, because |
| that would create ambiguity with the array <literal>||</literal> |
| operators. If you want to concatenate an array's text equivalent, |
| cast it to <type>text</type> explicitly.) |
| </para> |
| <para> |
| <literal>'Value: ' || 42</literal> |
| <returnvalue>Value: 42</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>normalized</primary> |
| </indexterm> |
| <indexterm> |
| <primary>Unicode normalization</primary> |
| </indexterm> |
| <type>text</type> <literal>IS</literal> <optional><literal>NOT</literal></optional> <optional><parameter>form</parameter></optional> <literal>NORMALIZED</literal> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Checks whether the string is in the specified Unicode normalization |
| form. The optional <parameter>form</parameter> key word specifies the |
| form: <literal>NFC</literal> (the default), <literal>NFD</literal>, |
| <literal>NFKC</literal>, or <literal>NFKD</literal>. This expression can |
| only be used when the server encoding is <literal>UTF8</literal>. Note |
| that checking for normalization using this expression is often faster |
| than normalizing possibly already normalized strings. |
| </para> |
| <para> |
| <literal>U&'\0061\0308bc' IS NFD NORMALIZED</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>bit_length</primary> |
| </indexterm> |
| <function>bit_length</function> ( <type>text</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns number of bits in the string (8 |
| times the <function>octet_length</function>). |
| </para> |
| <para> |
| <literal>bit_length('jose')</literal> |
| <returnvalue>32</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>char_length</primary> |
| </indexterm> |
| <indexterm> |
| <primary>character string</primary> |
| <secondary>length</secondary> |
| </indexterm> |
| <indexterm> |
| <primary>length</primary> |
| <secondary sortas="character string">of a character string</secondary> |
| <see>character string, length</see> |
| </indexterm> |
| <function>char_length</function> ( <type>text</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <indexterm> |
| <primary>character_length</primary> |
| </indexterm> |
| <function>character_length</function> ( <type>text</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns number of characters in the string. |
| </para> |
| <para> |
| <literal>char_length('josé')</literal> |
| <returnvalue>4</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>lower</primary> |
| </indexterm> |
| <function>lower</function> ( <type>text</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Converts the string to all lower case, according to the rules of the |
| database's locale. |
| </para> |
| <para> |
| <literal>lower('TOM')</literal> |
| <returnvalue>tom</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>normalize</primary> |
| </indexterm> |
| <indexterm> |
| <primary>Unicode normalization</primary> |
| </indexterm> |
| <function>normalize</function> ( <type>text</type> |
| <optional>, <parameter>form</parameter> </optional> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Converts the string to the specified Unicode |
| normalization form. The optional <parameter>form</parameter> key word |
| specifies the form: <literal>NFC</literal> (the default), |
| <literal>NFD</literal>, <literal>NFKC</literal>, or |
| <literal>NFKD</literal>. This function can only be used when the |
| server encoding is <literal>UTF8</literal>. |
| </para> |
| <para> |
| <literal>normalize(U&'\0061\0308bc', NFC)</literal> |
| <returnvalue>U&'\00E4bc'</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>octet_length</primary> |
| </indexterm> |
| <function>octet_length</function> ( <type>text</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns number of bytes in the string. |
| </para> |
| <para> |
| <literal>octet_length('josé')</literal> |
| <returnvalue>5</returnvalue> (if server encoding is UTF8) |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>octet_length</primary> |
| </indexterm> |
| <function>octet_length</function> ( <type>character</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns number of bytes in the string. Since this version of the |
| function accepts type <type>character</type> directly, it will not |
| strip trailing spaces. |
| </para> |
| <para> |
| <literal>octet_length('abc '::character(4))</literal> |
| <returnvalue>4</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>overlay</primary> |
| </indexterm> |
| <function>overlay</function> ( <parameter>string</parameter> <type>text</type> <literal>PLACING</literal> <parameter>newsubstring</parameter> <type>text</type> <literal>FROM</literal> <parameter>start</parameter> <type>integer</type> <optional> <literal>FOR</literal> <parameter>count</parameter> <type>integer</type> </optional> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Replaces the substring of <parameter>string</parameter> that starts at |
| the <parameter>start</parameter>'th character and extends |
| for <parameter>count</parameter> characters |
| with <parameter>newsubstring</parameter>. |
| If <parameter>count</parameter> is omitted, it defaults to the length |
| of <parameter>newsubstring</parameter>. |
| </para> |
| <para> |
| <literal>overlay('Txxxxas' placing 'hom' from 2 for 4)</literal> |
| <returnvalue>Thomas</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>position</primary> |
| </indexterm> |
| <function>position</function> ( <parameter>substring</parameter> <type>text</type> <literal>IN</literal> <parameter>string</parameter> <type>text</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns first starting index of the specified |
| <parameter>substring</parameter> within |
| <parameter>string</parameter>, or zero if it's not present. |
| </para> |
| <para> |
| <literal>position('om' in 'Thomas')</literal> |
| <returnvalue>3</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>substring</primary> |
| </indexterm> |
| <function>substring</function> ( <parameter>string</parameter> <type>text</type> <optional> <literal>FROM</literal> <parameter>start</parameter> <type>integer</type> </optional> <optional> <literal>FOR</literal> <parameter>count</parameter> <type>integer</type> </optional> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Extracts the substring of <parameter>string</parameter> starting at |
| the <parameter>start</parameter>'th character if that is specified, |
| and stopping after <parameter>count</parameter> characters if that is |
| specified. Provide at least one of <parameter>start</parameter> |
| and <parameter>count</parameter>. |
| </para> |
| <para> |
| <literal>substring('Thomas' from 2 for 3)</literal> |
| <returnvalue>hom</returnvalue> |
| </para> |
| <para> |
| <literal>substring('Thomas' from 3)</literal> |
| <returnvalue>omas</returnvalue> |
| </para> |
| <para> |
| <literal>substring('Thomas' for 2)</literal> |
| <returnvalue>Th</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>substring</function> ( <parameter>string</parameter> <type>text</type> <literal>FROM</literal> <parameter>pattern</parameter> <type>text</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Extracts the first substring matching POSIX regular expression; see |
| <xref linkend="functions-posix-regexp"/>. |
| </para> |
| <para> |
| <literal>substring('Thomas' from '...$')</literal> |
| <returnvalue>mas</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>substring</function> ( <parameter>string</parameter> <type>text</type> <literal>SIMILAR</literal> <parameter>pattern</parameter> <type>text</type> <literal>ESCAPE</literal> <parameter>escape</parameter> <type>text</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>substring</function> ( <parameter>string</parameter> <type>text</type> <literal>FROM</literal> <parameter>pattern</parameter> <type>text</type> <literal>FOR</literal> <parameter>escape</parameter> <type>text</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Extracts the first substring matching <acronym>SQL</acronym> regular expression; |
| see <xref linkend="functions-similarto-regexp"/>. The first form has |
| been specified since SQL:2003; the second form was only in SQL:1999 |
| and should be considered obsolete. |
| </para> |
| <para> |
| <literal>substring('Thomas' similar '%#"o_a#"_' escape '#')</literal> |
| <returnvalue>oma</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>trim</primary> |
| </indexterm> |
| <function>trim</function> ( <optional> <literal>LEADING</literal> | <literal>TRAILING</literal> | <literal>BOTH</literal> </optional> |
| <optional> <parameter>characters</parameter> <type>text</type> </optional> <literal>FROM</literal> |
| <parameter>string</parameter> <type>text</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Removes the longest string containing only characters in |
| <parameter>characters</parameter> (a space by default) from the |
| start, end, or both ends (<literal>BOTH</literal> is the default) |
| of <parameter>string</parameter>. |
| </para> |
| <para> |
| <literal>trim(both 'xyz' from 'yxTomxx')</literal> |
| <returnvalue>Tom</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>trim</function> ( <optional> <literal>LEADING</literal> | <literal>TRAILING</literal> | <literal>BOTH</literal> </optional> <optional> <literal>FROM</literal> </optional> |
| <parameter>string</parameter> <type>text</type> <optional>, |
| <parameter>characters</parameter> <type>text</type> </optional> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| This is a non-standard syntax for <function>trim()</function>. |
| </para> |
| <para> |
| <literal>trim(both from 'yxTomxx', 'xyz')</literal> |
| <returnvalue>Tom</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>upper</primary> |
| </indexterm> |
| <function>upper</function> ( <type>text</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Converts the string to all upper case, according to the rules of the |
| database's locale. |
| </para> |
| <para> |
| <literal>upper('tom')</literal> |
| <returnvalue>TOM</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| Additional string manipulation functions are available and are |
| listed in <xref linkend="functions-string-other"/>. Some of them are used internally to implement the |
| <acronym>SQL</acronym>-standard string functions listed in <xref linkend="functions-string-sql"/>. |
| </para> |
| |
| <table id="functions-string-other"> |
| <title>Other String Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>ascii</primary> |
| </indexterm> |
| <function>ascii</function> ( <type>text</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns the numeric code of the first character of the argument. |
| In <acronym>UTF8</acronym> encoding, returns the Unicode code point |
| of the character. In other multibyte encodings, the argument must |
| be an <acronym>ASCII</acronym> character. |
| </para> |
| <para> |
| <literal>ascii('x')</literal> |
| <returnvalue>120</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>btrim</primary> |
| </indexterm> |
| <function>btrim</function> ( <parameter>string</parameter> <type>text</type> |
| <optional>, <parameter>characters</parameter> <type>text</type> </optional> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Removes the longest string containing only characters |
| in <parameter>characters</parameter> (a space by default) |
| from the start and end of <parameter>string</parameter>. |
| </para> |
| <para> |
| <literal>btrim('xyxtrimyyx', 'xyz')</literal> |
| <returnvalue>trim</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>chr</primary> |
| </indexterm> |
| <function>chr</function> ( <type>integer</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Returns the character with the given code. In <acronym>UTF8</acronym> |
| encoding the argument is treated as a Unicode code point. In other |
| multibyte encodings the argument must designate |
| an <acronym>ASCII</acronym> character. <literal>chr(0)</literal> is |
| disallowed because text data types cannot store that character. |
| </para> |
| <para> |
| <literal>chr(65)</literal> |
| <returnvalue>A</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>concat</primary> |
| </indexterm> |
| <function>concat</function> ( <parameter>val1</parameter> <type>"any"</type> |
| [, <parameter>val2</parameter> <type>"any"</type> [, ...] ] ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Concatenates the text representations of all the arguments. |
| NULL arguments are ignored. |
| </para> |
| <para> |
| <literal>concat('abcde', 2, NULL, 22)</literal> |
| <returnvalue>abcde222</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>concat_ws</primary> |
| </indexterm> |
| <function>concat_ws</function> ( <parameter>sep</parameter> <type>text</type>, |
| <parameter>val1</parameter> <type>"any"</type> |
| [, <parameter>val2</parameter> <type>"any"</type> [, ...] ] ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Concatenates all but the first argument, with separators. The first |
| argument is used as the separator string, and should not be NULL. |
| Other NULL arguments are ignored. |
| </para> |
| <para> |
| <literal>concat_ws(',', 'abcde', 2, NULL, 22)</literal> |
| <returnvalue>abcde,2,22</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>format</primary> |
| </indexterm> |
| <function>format</function> ( <parameter>formatstr</parameter> <type>text</type> |
| [, <parameter>formatarg</parameter> <type>"any"</type> [, ...] ] ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Formats arguments according to a format string; |
| see <xref linkend="functions-string-format"/>. |
| This function is similar to the C function <function>sprintf</function>. |
| </para> |
| <para> |
| <literal>format('Hello %s, %1$s', 'World')</literal> |
| <returnvalue>Hello World, World</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>initcap</primary> |
| </indexterm> |
| <function>initcap</function> ( <type>text</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Converts the first letter of each word to upper case and the |
| rest to lower case. Words are sequences of alphanumeric |
| characters separated by non-alphanumeric characters. |
| </para> |
| <para> |
| <literal>initcap('hi THOMAS')</literal> |
| <returnvalue>Hi Thomas</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>left</primary> |
| </indexterm> |
| <function>left</function> ( <parameter>string</parameter> <type>text</type>, |
| <parameter>n</parameter> <type>integer</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Returns first <parameter>n</parameter> characters in the |
| string, or when <parameter>n</parameter> is negative, returns |
| all but last |<parameter>n</parameter>| characters. |
| </para> |
| <para> |
| <literal>left('abcde', 2)</literal> |
| <returnvalue>ab</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>length</primary> |
| </indexterm> |
| <function>length</function> ( <type>text</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns the number of characters in the string. |
| </para> |
| <para> |
| <literal>length('jose')</literal> |
| <returnvalue>4</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>lpad</primary> |
| </indexterm> |
| <function>lpad</function> ( <parameter>string</parameter> <type>text</type>, |
| <parameter>length</parameter> <type>integer</type> |
| <optional>, <parameter>fill</parameter> <type>text</type> </optional> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Extends the <parameter>string</parameter> to length |
| <parameter>length</parameter> by prepending the characters |
| <parameter>fill</parameter> (a space by default). If the |
| <parameter>string</parameter> is already longer than |
| <parameter>length</parameter> then it is truncated (on the right). |
| </para> |
| <para> |
| <literal>lpad('hi', 5, 'xy')</literal> |
| <returnvalue>xyxhi</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>ltrim</primary> |
| </indexterm> |
| <function>ltrim</function> ( <parameter>string</parameter> <type>text</type> |
| <optional>, <parameter>characters</parameter> <type>text</type> </optional> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Removes the longest string containing only characters in |
| <parameter>characters</parameter> (a space by default) from the start of |
| <parameter>string</parameter>. |
| </para> |
| <para> |
| <literal>ltrim('zzzytest', 'xyz')</literal> |
| <returnvalue>test</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>md5</primary> |
| </indexterm> |
| <function>md5</function> ( <type>text</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Computes the MD5 <link linkend="functions-hash-note">hash</link> of |
| the argument, with the result written in hexadecimal. |
| </para> |
| <para> |
| <literal>md5('abc')</literal> |
| <returnvalue>900150983cd24fb0&zwsp;d6963f7d28e17f72</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>parse_ident</primary> |
| </indexterm> |
| <function>parse_ident</function> ( <parameter>qualified_identifier</parameter> <type>text</type> |
| [, <parameter>strict_mode</parameter> <type>boolean</type> <literal>DEFAULT</literal> <literal>true</literal> ] ) |
| <returnvalue>text[]</returnvalue> |
| </para> |
| <para> |
| Splits <parameter>qualified_identifier</parameter> into an array of |
| identifiers, removing any quoting of individual identifiers. By |
| default, extra characters after the last identifier are considered an |
| error; but if the second parameter is <literal>false</literal>, then such |
| extra characters are ignored. (This behavior is useful for parsing |
| names for objects like functions.) Note that this function does not |
| truncate over-length identifiers. If you want truncation you can cast |
| the result to <type>name[]</type>. |
| </para> |
| <para> |
| <literal>parse_ident('"SomeSchema".someTable')</literal> |
| <returnvalue>{SomeSchema,sometable}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_client_encoding</primary> |
| </indexterm> |
| <function>pg_client_encoding</function> ( ) |
| <returnvalue>name</returnvalue> |
| </para> |
| <para> |
| Returns current client encoding name. |
| </para> |
| <para> |
| <literal>pg_client_encoding()</literal> |
| <returnvalue>UTF8</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>quote_ident</primary> |
| </indexterm> |
| <function>quote_ident</function> ( <type>text</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Returns the given string suitably quoted to be used as an identifier |
| in an <acronym>SQL</acronym> statement string. |
| Quotes are added only if necessary (i.e., if the string contains |
| non-identifier characters or would be case-folded). |
| Embedded quotes are properly doubled. |
| See also <xref linkend="plpgsql-quote-literal-example"/>. |
| </para> |
| <para> |
| <literal>quote_ident('Foo bar')</literal> |
| <returnvalue>"Foo bar"</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>quote_literal</primary> |
| </indexterm> |
| <function>quote_literal</function> ( <type>text</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Returns the given string suitably quoted to be used as a string literal |
| in an <acronym>SQL</acronym> statement string. |
| Embedded single-quotes and backslashes are properly doubled. |
| Note that <function>quote_literal</function> returns null on null |
| input; if the argument might be null, |
| <function>quote_nullable</function> is often more suitable. |
| See also <xref linkend="plpgsql-quote-literal-example"/>. |
| </para> |
| <para> |
| <literal>quote_literal(E'O\'Reilly')</literal> |
| <returnvalue>'O''Reilly'</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>quote_literal</function> ( <type>anyelement</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Converts the given value to text and then quotes it as a literal. |
| Embedded single-quotes and backslashes are properly doubled. |
| </para> |
| <para> |
| <literal>quote_literal(42.5)</literal> |
| <returnvalue>'42.5'</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>quote_nullable</primary> |
| </indexterm> |
| <function>quote_nullable</function> ( <type>text</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Returns the given string suitably quoted to be used as a string literal |
| in an <acronym>SQL</acronym> statement string; or, if the argument |
| is null, returns <literal>NULL</literal>. |
| Embedded single-quotes and backslashes are properly doubled. |
| See also <xref linkend="plpgsql-quote-literal-example"/>. |
| </para> |
| <para> |
| <literal>quote_nullable(NULL)</literal> |
| <returnvalue>NULL</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>quote_nullable</function> ( <type>anyelement</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Converts the given value to text and then quotes it as a literal; |
| or, if the argument is null, returns <literal>NULL</literal>. |
| Embedded single-quotes and backslashes are properly doubled. |
| </para> |
| <para> |
| <literal>quote_nullable(42.5)</literal> |
| <returnvalue>'42.5'</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>regexp_match</primary> |
| </indexterm> |
| <function>regexp_match</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type> ] ) |
| <returnvalue>text[]</returnvalue> |
| </para> |
| <para> |
| Returns captured substrings resulting from the first match of a POSIX |
| regular expression to the <parameter>string</parameter>; see |
| <xref linkend="functions-posix-regexp"/>. |
| </para> |
| <para> |
| <literal>regexp_match('foobarbequebaz', '(bar)(beque)')</literal> |
| <returnvalue>{bar,beque}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>regexp_matches</primary> |
| </indexterm> |
| <function>regexp_matches</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type> ] ) |
| <returnvalue>setof text[]</returnvalue> |
| </para> |
| <para> |
| Returns captured substrings resulting from the first match of a |
| POSIX regular expression to the <parameter>string</parameter>, |
| or multiple matches if the <literal>g</literal> flag is used; |
| see <xref linkend="functions-posix-regexp"/>. |
| </para> |
| <para> |
| <literal>regexp_matches('foobarbequebaz', 'ba.', 'g')</literal> |
| <returnvalue></returnvalue> |
| <programlisting> |
| {bar} |
| {baz} |
| </programlisting> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>regexp_replace</primary> |
| </indexterm> |
| <function>regexp_replace</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>, <parameter>replacement</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type> ] ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Replaces substrings resulting from the first match of a |
| POSIX regular expression, or multiple substring matches |
| if the <literal>g</literal> flag is used; see <xref |
| linkend="functions-posix-regexp"/>. |
| </para> |
| <para> |
| <literal>regexp_replace('Thomas', '.[mN]a.', 'M')</literal> |
| <returnvalue>ThM</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>regexp_split_to_array</primary> |
| </indexterm> |
| <function>regexp_split_to_array</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type> ] ) |
| <returnvalue>text[]</returnvalue> |
| </para> |
| <para> |
| Splits <parameter>string</parameter> using a POSIX regular |
| expression as the delimiter, producing an array of results; see |
| <xref linkend="functions-posix-regexp"/>. |
| </para> |
| <para> |
| <literal>regexp_split_to_array('hello world', '\s+')</literal> |
| <returnvalue>{hello,world}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>regexp_split_to_table</primary> |
| </indexterm> |
| <function>regexp_split_to_table</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type> ] ) |
| <returnvalue>setof text</returnvalue> |
| </para> |
| <para> |
| Splits <parameter>string</parameter> using a POSIX regular |
| expression as the delimiter, producing a set of results; see |
| <xref linkend="functions-posix-regexp"/>. |
| </para> |
| <para> |
| <literal>regexp_split_to_table('hello world', '\s+')</literal> |
| <returnvalue></returnvalue> |
| <programlisting> |
| hello |
| world |
| </programlisting> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>repeat</primary> |
| </indexterm> |
| <function>repeat</function> ( <parameter>string</parameter> <type>text</type>, <parameter>number</parameter> <type>integer</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Repeats <parameter>string</parameter> the specified |
| <parameter>number</parameter> of times. |
| </para> |
| <para> |
| <literal>repeat('Pg', 4)</literal> |
| <returnvalue>PgPgPgPg</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>replace</primary> |
| </indexterm> |
| <function>replace</function> ( <parameter>string</parameter> <type>text</type>, |
| <parameter>from</parameter> <type>text</type>, |
| <parameter>to</parameter> <type>text</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Replaces all occurrences in <parameter>string</parameter> of |
| substring <parameter>from</parameter> with |
| substring <parameter>to</parameter>. |
| </para> |
| <para> |
| <literal>replace('abcdefabcdef', 'cd', 'XX')</literal> |
| <returnvalue>abXXefabXXef</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>reverse</primary> |
| </indexterm> |
| <function>reverse</function> ( <type>text</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Reverses the order of the characters in the string. |
| </para> |
| <para> |
| <literal>reverse('abcde')</literal> |
| <returnvalue>edcba</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>right</primary> |
| </indexterm> |
| <function>right</function> ( <parameter>string</parameter> <type>text</type>, |
| <parameter>n</parameter> <type>integer</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Returns last <parameter>n</parameter> characters in the string, |
| or when <parameter>n</parameter> is negative, returns all but |
| first |<parameter>n</parameter>| characters. |
| </para> |
| <para> |
| <literal>right('abcde', 2)</literal> |
| <returnvalue>de</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>rpad</primary> |
| </indexterm> |
| <function>rpad</function> ( <parameter>string</parameter> <type>text</type>, |
| <parameter>length</parameter> <type>integer</type> |
| <optional>, <parameter>fill</parameter> <type>text</type> </optional> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Extends the <parameter>string</parameter> to length |
| <parameter>length</parameter> by appending the characters |
| <parameter>fill</parameter> (a space by default). If the |
| <parameter>string</parameter> is already longer than |
| <parameter>length</parameter> then it is truncated. |
| </para> |
| <para> |
| <literal>rpad('hi', 5, 'xy')</literal> |
| <returnvalue>hixyx</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>rtrim</primary> |
| </indexterm> |
| <function>rtrim</function> ( <parameter>string</parameter> <type>text</type> |
| <optional>, <parameter>characters</parameter> <type>text</type> </optional> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Removes the longest string containing only characters in |
| <parameter>characters</parameter> (a space by default) from the end of |
| <parameter>string</parameter>. |
| </para> |
| <para> |
| <literal>rtrim('testxxzx', 'xyz')</literal> |
| <returnvalue>test</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>split_part</primary> |
| </indexterm> |
| <function>split_part</function> ( <parameter>string</parameter> <type>text</type>, |
| <parameter>delimiter</parameter> <type>text</type>, |
| <parameter>n</parameter> <type>integer</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Splits <parameter>string</parameter> at occurrences |
| of <parameter>delimiter</parameter> and returns |
| the <parameter>n</parameter>'th field (counting from one), |
| or when <parameter>n</parameter> is negative, returns |
| the |<parameter>n</parameter>|'th-from-last field. |
| </para> |
| <para> |
| <literal>split_part('abc~@~def~@~ghi', '~@~', 2)</literal> |
| <returnvalue>def</returnvalue> |
| </para> |
| <para> |
| <literal>split_part('abc,def,ghi,jkl', ',', -2)</literal> |
| <returnvalue>ghi</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>strpos</primary> |
| </indexterm> |
| <function>strpos</function> ( <parameter>string</parameter> <type>text</type>, <parameter>substring</parameter> <type>text</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns first starting index of the specified <parameter>substring</parameter> |
| within <parameter>string</parameter>, or zero if it's not present. |
| (Same as <literal>position(<parameter>substring</parameter> in |
| <parameter>string</parameter>)</literal>, but note the reversed |
| argument order.) |
| </para> |
| <para> |
| <literal>strpos('high', 'ig')</literal> |
| <returnvalue>2</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>substr</primary> |
| </indexterm> |
| <function>substr</function> ( <parameter>string</parameter> <type>text</type>, <parameter>start</parameter> <type>integer</type> <optional>, <parameter>count</parameter> <type>integer</type> </optional> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Extracts the substring of <parameter>string</parameter> starting at |
| the <parameter>start</parameter>'th character, |
| and extending for <parameter>count</parameter> characters if that is |
| specified. (Same |
| as <literal>substring(<parameter>string</parameter> |
| from <parameter>start</parameter> |
| for <parameter>count</parameter>)</literal>.) |
| </para> |
| <para> |
| <literal>substr('alphabet', 3)</literal> |
| <returnvalue>phabet</returnvalue> |
| </para> |
| <para> |
| <literal>substr('alphabet', 3, 2)</literal> |
| <returnvalue>ph</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>starts_with</primary> |
| </indexterm> |
| <function>starts_with</function> ( <parameter>string</parameter> <type>text</type>, <parameter>prefix</parameter> <type>text</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Returns true if <parameter>string</parameter> starts |
| with <parameter>prefix</parameter>. |
| </para> |
| <para> |
| <literal>starts_with('alphabet', 'alph')</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>string_to_array</primary> |
| </indexterm> |
| <function>string_to_array</function> ( <parameter>string</parameter> <type>text</type>, <parameter>delimiter</parameter> <type>text</type> <optional>, <parameter>null_string</parameter> <type>text</type> </optional> ) |
| <returnvalue>text[]</returnvalue> |
| </para> |
| <para> |
| Splits the <parameter>string</parameter> at occurrences |
| of <parameter>delimiter</parameter> and forms the resulting fields |
| into a <type>text</type> array. |
| If <parameter>delimiter</parameter> is <literal>NULL</literal>, |
| each character in the <parameter>string</parameter> will become a |
| separate element in the array. |
| If <parameter>delimiter</parameter> is an empty string, then |
| the <parameter>string</parameter> is treated as a single field. |
| If <parameter>null_string</parameter> is supplied and is |
| not <literal>NULL</literal>, fields matching that string are |
| replaced by <literal>NULL</literal>. |
| </para> |
| <para> |
| <literal>string_to_array('xx~~yy~~zz', '~~', 'yy')</literal> |
| <returnvalue>{xx,NULL,zz}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>string_to_table</primary> |
| </indexterm> |
| <function>string_to_table</function> ( <parameter>string</parameter> <type>text</type>, <parameter>delimiter</parameter> <type>text</type> <optional>, <parameter>null_string</parameter> <type>text</type> </optional> ) |
| <returnvalue>setof text</returnvalue> |
| </para> |
| <para> |
| Splits the <parameter>string</parameter> at occurrences |
| of <parameter>delimiter</parameter> and returns the resulting fields |
| as a set of <type>text</type> rows. |
| If <parameter>delimiter</parameter> is <literal>NULL</literal>, |
| each character in the <parameter>string</parameter> will become a |
| separate row of the result. |
| If <parameter>delimiter</parameter> is an empty string, then |
| the <parameter>string</parameter> is treated as a single field. |
| If <parameter>null_string</parameter> is supplied and is |
| not <literal>NULL</literal>, fields matching that string are |
| replaced by <literal>NULL</literal>. |
| </para> |
| <para> |
| <literal>string_to_table('xx~^~yy~^~zz', '~^~', 'yy')</literal> |
| <returnvalue></returnvalue> |
| <programlisting> |
| xx |
| NULL |
| zz |
| </programlisting> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>to_ascii</primary> |
| </indexterm> |
| <function>to_ascii</function> ( <parameter>string</parameter> <type>text</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>to_ascii</function> ( <parameter>string</parameter> <type>text</type>, |
| <parameter>encoding</parameter> <type>name</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>to_ascii</function> ( <parameter>string</parameter> <type>text</type>, |
| <parameter>encoding</parameter> <type>integer</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Converts <parameter>string</parameter> to <acronym>ASCII</acronym> |
| from another encoding, which may be identified by name or number. |
| If <parameter>encoding</parameter> is omitted the database encoding |
| is assumed (which in practice is the only useful case). |
| The conversion consists primarily of dropping accents. |
| Conversion is only supported |
| from <literal>LATIN1</literal>, <literal>LATIN2</literal>, |
| <literal>LATIN9</literal>, and <literal>WIN1250</literal> encodings. |
| (See the <xref linkend="unaccent"/> module for another, more flexible |
| solution.) |
| </para> |
| <para> |
| <literal>to_ascii('Karél')</literal> |
| <returnvalue>Karel</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>to_hex</primary> |
| </indexterm> |
| <function>to_hex</function> ( <type>integer</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>to_hex</function> ( <type>bigint</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Converts the number to its equivalent hexadecimal representation. |
| </para> |
| <para> |
| <literal>to_hex(2147483647)</literal> |
| <returnvalue>7fffffff</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>translate</primary> |
| </indexterm> |
| <function>translate</function> ( <parameter>string</parameter> <type>text</type>, |
| <parameter>from</parameter> <type>text</type>, |
| <parameter>to</parameter> <type>text</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Replaces each character in <parameter>string</parameter> that |
| matches a character in the <parameter>from</parameter> set with the |
| corresponding character in the <parameter>to</parameter> |
| set. If <parameter>from</parameter> is longer than |
| <parameter>to</parameter>, occurrences of the extra characters in |
| <parameter>from</parameter> are deleted. |
| </para> |
| <para> |
| <literal>translate('12345', '143', 'ax')</literal> |
| <returnvalue>a2x5</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>unistr</primary> |
| </indexterm> |
| <function>unistr</function> ( <type>text</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Evaluate escaped Unicode characters in the argument. Unicode characters |
| can be specified as |
| <literal>\<replaceable>XXXX</replaceable></literal> (4 hexadecimal |
| digits), <literal>\+<replaceable>XXXXXX</replaceable></literal> (6 |
| hexadecimal digits), |
| <literal>\u<replaceable>XXXX</replaceable></literal> (4 hexadecimal |
| digits), or <literal>\U<replaceable>XXXXXXXX</replaceable></literal> |
| (8 hexadecimal digits). To specify a backslash, write two |
| backslashes. All other characters are taken literally. |
| </para> |
| |
| <para> |
| If the server encoding is not UTF-8, the Unicode code point identified |
| by one of these escape sequences is converted to the actual server |
| encoding; an error is reported if that's not possible. |
| </para> |
| |
| <para> |
| This function provides a (non-standard) alternative to string |
| constants with Unicode escapes (see <xref |
| linkend="sql-syntax-strings-uescape"/>). |
| </para> |
| |
| <para> |
| <literal>unistr('d\0061t\+000061')</literal> |
| <returnvalue>data</returnvalue> |
| </para> |
| <para> |
| <literal>unistr('d\u0061t\U00000061')</literal> |
| <returnvalue>data</returnvalue> |
| </para></entry> |
| </row> |
| |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| The <function>concat</function>, <function>concat_ws</function> and |
| <function>format</function> functions are variadic, so it is possible to |
| pass the values to be concatenated or formatted as an array marked with |
| the <literal>VARIADIC</literal> keyword (see <xref |
| linkend="xfunc-sql-variadic-functions"/>). The array's elements are |
| treated as if they were separate ordinary arguments to the function. |
| If the variadic array argument is NULL, <function>concat</function> |
| and <function>concat_ws</function> return NULL, but |
| <function>format</function> treats a NULL as a zero-element array. |
| </para> |
| |
| <para> |
| See also the aggregate function <function>string_agg</function> in |
| <xref linkend="functions-aggregate"/>, and the functions for |
| converting between strings and the <type>bytea</type> type in |
| <xref linkend="functions-binarystring-conversions"/>. |
| </para> |
| |
| <sect2 id="functions-string-format"> |
| <title><function>format</function></title> |
| |
| <indexterm> |
| <primary>format</primary> |
| </indexterm> |
| |
| <para> |
| The function <function>format</function> produces output formatted according to |
| a format string, in a style similar to the C function |
| <function>sprintf</function>. |
| </para> |
| |
| <para> |
| <synopsis> |
| <function>format</function>(<parameter>formatstr</parameter> <type>text</type> [, <parameter>formatarg</parameter> <type>"any"</type> [, ...] ]) |
| </synopsis> |
| <parameter>formatstr</parameter> is a format string that specifies how the |
| result should be formatted. Text in the format string is copied |
| directly to the result, except where <firstterm>format specifiers</firstterm> are |
| used. Format specifiers act as placeholders in the string, defining how |
| subsequent function arguments should be formatted and inserted into the |
| result. Each <parameter>formatarg</parameter> argument is converted to text |
| according to the usual output rules for its data type, and then formatted |
| and inserted into the result string according to the format specifier(s). |
| </para> |
| |
| <para> |
| Format specifiers are introduced by a <literal>%</literal> character and have |
| the form |
| <synopsis> |
| %[<parameter>position</parameter>][<parameter>flags</parameter>][<parameter>width</parameter>]<parameter>type</parameter> |
| </synopsis> |
| where the component fields are: |
| |
| <variablelist> |
| <varlistentry> |
| <term><parameter>position</parameter> (optional)</term> |
| <listitem> |
| <para> |
| A string of the form <literal><parameter>n</parameter>$</literal> where |
| <parameter>n</parameter> is the index of the argument to print. |
| Index 1 means the first argument after |
| <parameter>formatstr</parameter>. If the <parameter>position</parameter> is |
| omitted, the default is to use the next argument in sequence. |
| </para> |
| </listitem> |
| </varlistentry> |
| |
| <varlistentry> |
| <term><parameter>flags</parameter> (optional)</term> |
| <listitem> |
| <para> |
| Additional options controlling how the format specifier's output is |
| formatted. Currently the only supported flag is a minus sign |
| (<literal>-</literal>) which will cause the format specifier's output to be |
| left-justified. This has no effect unless the <parameter>width</parameter> |
| field is also specified. |
| </para> |
| </listitem> |
| </varlistentry> |
| |
| <varlistentry> |
| <term><parameter>width</parameter> (optional)</term> |
| <listitem> |
| <para> |
| Specifies the <emphasis>minimum</emphasis> number of characters to use to |
| display the format specifier's output. The output is padded on the |
| left or right (depending on the <literal>-</literal> flag) with spaces as |
| needed to fill the width. A too-small width does not cause |
| truncation of the output, but is simply ignored. The width may be |
| specified using any of the following: a positive integer; an |
| asterisk (<literal>*</literal>) to use the next function argument as the |
| width; or a string of the form <literal>*<parameter>n</parameter>$</literal> to |
| use the <parameter>n</parameter>th function argument as the width. |
| </para> |
| |
| <para> |
| If the width comes from a function argument, that argument is |
| consumed before the argument that is used for the format specifier's |
| value. If the width argument is negative, the result is left |
| aligned (as if the <literal>-</literal> flag had been specified) within a |
| field of length <function>abs</function>(<parameter>width</parameter>). |
| </para> |
| </listitem> |
| </varlistentry> |
| |
| <varlistentry> |
| <term><parameter>type</parameter> (required)</term> |
| <listitem> |
| <para> |
| The type of format conversion to use to produce the format |
| specifier's output. The following types are supported: |
| <itemizedlist> |
| <listitem> |
| <para> |
| <literal>s</literal> formats the argument value as a simple |
| string. A null value is treated as an empty string. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| <literal>I</literal> treats the argument value as an SQL |
| identifier, double-quoting it if necessary. |
| It is an error for the value to be null (equivalent to |
| <function>quote_ident</function>). |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| <literal>L</literal> quotes the argument value as an SQL literal. |
| A null value is displayed as the string <literal>NULL</literal>, without |
| quotes (equivalent to <function>quote_nullable</function>). |
| </para> |
| </listitem> |
| </itemizedlist> |
| </para> |
| </listitem> |
| </varlistentry> |
| </variablelist> |
| </para> |
| |
| <para> |
| In addition to the format specifiers described above, the special sequence |
| <literal>%%</literal> may be used to output a literal <literal>%</literal> character. |
| </para> |
| |
| <para> |
| Here are some examples of the basic format conversions: |
| |
| <screen> |
| SELECT format('Hello %s', 'World'); |
| <lineannotation>Result: </lineannotation><computeroutput>Hello World</computeroutput> |
| |
| SELECT format('Testing %s, %s, %s, %%', 'one', 'two', 'three'); |
| <lineannotation>Result: </lineannotation><computeroutput>Testing one, two, three, %</computeroutput> |
| |
| SELECT format('INSERT INTO %I VALUES(%L)', 'Foo bar', E'O\'Reilly'); |
| <lineannotation>Result: </lineannotation><computeroutput>INSERT INTO "Foo bar" VALUES('O''Reilly')</computeroutput> |
| |
| SELECT format('INSERT INTO %I VALUES(%L)', 'locations', 'C:\Program Files'); |
| <lineannotation>Result: </lineannotation><computeroutput>INSERT INTO locations VALUES('C:\Program Files')</computeroutput> |
| </screen> |
| </para> |
| |
| <para> |
| Here are examples using <parameter>width</parameter> fields |
| and the <literal>-</literal> flag: |
| |
| <screen> |
| SELECT format('|%10s|', 'foo'); |
| <lineannotation>Result: </lineannotation><computeroutput>| foo|</computeroutput> |
| |
| SELECT format('|%-10s|', 'foo'); |
| <lineannotation>Result: </lineannotation><computeroutput>|foo |</computeroutput> |
| |
| SELECT format('|%*s|', 10, 'foo'); |
| <lineannotation>Result: </lineannotation><computeroutput>| foo|</computeroutput> |
| |
| SELECT format('|%*s|', -10, 'foo'); |
| <lineannotation>Result: </lineannotation><computeroutput>|foo |</computeroutput> |
| |
| SELECT format('|%-*s|', 10, 'foo'); |
| <lineannotation>Result: </lineannotation><computeroutput>|foo |</computeroutput> |
| |
| SELECT format('|%-*s|', -10, 'foo'); |
| <lineannotation>Result: </lineannotation><computeroutput>|foo |</computeroutput> |
| </screen> |
| </para> |
| |
| <para> |
| These examples show use of <parameter>position</parameter> fields: |
| |
| <screen> |
| SELECT format('Testing %3$s, %2$s, %1$s', 'one', 'two', 'three'); |
| <lineannotation>Result: </lineannotation><computeroutput>Testing three, two, one</computeroutput> |
| |
| SELECT format('|%*2$s|', 'foo', 10, 'bar'); |
| <lineannotation>Result: </lineannotation><computeroutput>| bar|</computeroutput> |
| |
| SELECT format('|%1$*2$s|', 'foo', 10, 'bar'); |
| <lineannotation>Result: </lineannotation><computeroutput>| foo|</computeroutput> |
| </screen> |
| </para> |
| |
| <para> |
| Unlike the standard C function <function>sprintf</function>, |
| <productname>PostgreSQL</productname>'s <function>format</function> function allows format |
| specifiers with and without <parameter>position</parameter> fields to be mixed |
| in the same format string. A format specifier without a |
| <parameter>position</parameter> field always uses the next argument after the |
| last argument consumed. |
| In addition, the <function>format</function> function does not require all |
| function arguments to be used in the format string. |
| For example: |
| |
| <screen> |
| SELECT format('Testing %3$s, %2$s, %s', 'one', 'two', 'three'); |
| <lineannotation>Result: </lineannotation><computeroutput>Testing three, two, three</computeroutput> |
| </screen> |
| </para> |
| |
| <para> |
| The <literal>%I</literal> and <literal>%L</literal> format specifiers are particularly |
| useful for safely constructing dynamic SQL statements. See |
| <xref linkend="plpgsql-quote-literal-example"/>. |
| </para> |
| </sect2> |
| |
| </sect1> |
| |
| |
| <sect1 id="functions-binarystring"> |
| <title>Binary String Functions and Operators</title> |
| |
| <indexterm zone="functions-binarystring"> |
| <primary>binary data</primary> |
| <secondary>functions</secondary> |
| </indexterm> |
| |
| <para> |
| This section describes functions and operators for examining and |
| manipulating binary strings, that is values of type <type>bytea</type>. |
| Many of these are equivalent, in purpose and syntax, to the |
| text-string functions described in the previous section. |
| </para> |
| |
| <para> |
| <acronym>SQL</acronym> defines some string functions that use |
| key words, rather than commas, to separate |
| arguments. Details are in |
| <xref linkend="functions-binarystring-sql"/>. |
| <productname>PostgreSQL</productname> also provides versions of these functions |
| that use the regular function invocation syntax |
| (see <xref linkend="functions-binarystring-other"/>). |
| </para> |
| |
| <table id="functions-binarystring-sql"> |
| <title><acronym>SQL</acronym> Binary String Functions and Operators</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function/Operator |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>binary string</primary> |
| <secondary>concatenation</secondary> |
| </indexterm> |
| <type>bytea</type> <literal>||</literal> <type>bytea</type> |
| <returnvalue>bytea</returnvalue> |
| </para> |
| <para> |
| Concatenates the two binary strings. |
| </para> |
| <para> |
| <literal>'\x123456'::bytea || '\x789a00bcde'::bytea</literal> |
| <returnvalue>\x123456789a00bcde</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>bit_length</primary> |
| </indexterm> |
| <function>bit_length</function> ( <type>bytea</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns number of bits in the binary string (8 |
| times the <function>octet_length</function>). |
| </para> |
| <para> |
| <literal>bit_length('\x123456'::bytea)</literal> |
| <returnvalue>24</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>octet_length</primary> |
| </indexterm> |
| <function>octet_length</function> ( <type>bytea</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns number of bytes in the binary string. |
| </para> |
| <para> |
| <literal>octet_length('\x123456'::bytea)</literal> |
| <returnvalue>3</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>overlay</primary> |
| </indexterm> |
| <function>overlay</function> ( <parameter>bytes</parameter> <type>bytea</type> <literal>PLACING</literal> <parameter>newsubstring</parameter> <type>bytea</type> <literal>FROM</literal> <parameter>start</parameter> <type>integer</type> <optional> <literal>FOR</literal> <parameter>count</parameter> <type>integer</type> </optional> ) |
| <returnvalue>bytea</returnvalue> |
| </para> |
| <para> |
| Replaces the substring of <parameter>bytes</parameter> that starts at |
| the <parameter>start</parameter>'th byte and extends |
| for <parameter>count</parameter> bytes |
| with <parameter>newsubstring</parameter>. |
| If <parameter>count</parameter> is omitted, it defaults to the length |
| of <parameter>newsubstring</parameter>. |
| </para> |
| <para> |
| <literal>overlay('\x1234567890'::bytea placing '\002\003'::bytea from 2 for 3)</literal> |
| <returnvalue>\x12020390</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>position</primary> |
| </indexterm> |
| <function>position</function> ( <parameter>substring</parameter> <type>bytea</type> <literal>IN</literal> <parameter>bytes</parameter> <type>bytea</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns first starting index of the specified |
| <parameter>substring</parameter> within |
| <parameter>bytes</parameter>, or zero if it's not present. |
| </para> |
| <para> |
| <literal>position('\x5678'::bytea in '\x1234567890'::bytea)</literal> |
| <returnvalue>3</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>substring</primary> |
| </indexterm> |
| <function>substring</function> ( <parameter>bytes</parameter> <type>bytea</type> <optional> <literal>FROM</literal> <parameter>start</parameter> <type>integer</type> </optional> <optional> <literal>FOR</literal> <parameter>count</parameter> <type>integer</type> </optional> ) |
| <returnvalue>bytea</returnvalue> |
| </para> |
| <para> |
| Extracts the substring of <parameter>bytes</parameter> starting at |
| the <parameter>start</parameter>'th byte if that is specified, |
| and stopping after <parameter>count</parameter> bytes if that is |
| specified. Provide at least one of <parameter>start</parameter> |
| and <parameter>count</parameter>. |
| </para> |
| <para> |
| <literal>substring('\x1234567890'::bytea from 3 for 2)</literal> |
| <returnvalue>\x5678</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>trim</primary> |
| </indexterm> |
| <function>trim</function> ( <optional> <literal>LEADING</literal> | <literal>TRAILING</literal> | <literal>BOTH</literal> </optional> |
| <parameter>bytesremoved</parameter> <type>bytea</type> <literal>FROM</literal> |
| <parameter>bytes</parameter> <type>bytea</type> ) |
| <returnvalue>bytea</returnvalue> |
| </para> |
| <para> |
| Removes the longest string containing only bytes appearing in |
| <parameter>bytesremoved</parameter> from the start, |
| end, or both ends (<literal>BOTH</literal> is the default) |
| of <parameter>bytes</parameter>. |
| </para> |
| <para> |
| <literal>trim('\x9012'::bytea from '\x1234567890'::bytea)</literal> |
| <returnvalue>\x345678</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>trim</function> ( <optional> <literal>LEADING</literal> | <literal>TRAILING</literal> | <literal>BOTH</literal> </optional> <optional> <literal>FROM</literal> </optional> |
| <parameter>bytes</parameter> <type>bytea</type>, |
| <parameter>bytesremoved</parameter> <type>bytea</type> ) |
| <returnvalue>bytea</returnvalue> |
| </para> |
| <para> |
| This is a non-standard syntax for <function>trim()</function>. |
| </para> |
| <para> |
| <literal>trim(both from '\x1234567890'::bytea, '\x9012'::bytea)</literal> |
| <returnvalue>\x345678</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| Additional binary string manipulation functions are available and |
| are listed in <xref linkend="functions-binarystring-other"/>. Some |
| of them are used internally to implement the |
| <acronym>SQL</acronym>-standard string functions listed in <xref |
| linkend="functions-binarystring-sql"/>. |
| </para> |
| |
| <table id="functions-binarystring-other"> |
| <title>Other Binary String Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>bit_count</primary> |
| </indexterm> |
| <indexterm> |
| <primary>popcount</primary> |
| <see>bit_count</see> |
| </indexterm> |
| <function>bit_count</function> ( <parameter>bytes</parameter> <type>bytea</type> ) |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para> |
| Returns the number of bits set in the binary string (also known as |
| <quote>popcount</quote>). |
| </para> |
| <para> |
| <literal>bit_count('\x1234567890'::bytea)</literal> |
| <returnvalue>15</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>btrim</primary> |
| </indexterm> |
| <function>btrim</function> ( <parameter>bytes</parameter> <type>bytea</type>, |
| <parameter>bytesremoved</parameter> <type>bytea</type> ) |
| <returnvalue>bytea</returnvalue> |
| </para> |
| <para> |
| Removes the longest string containing only bytes appearing in |
| <parameter>bytesremoved</parameter> from the start and end of |
| <parameter>bytes</parameter>. |
| </para> |
| <para> |
| <literal>btrim('\x1234567890'::bytea, '\x9012'::bytea)</literal> |
| <returnvalue>\x345678</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>get_bit</primary> |
| </indexterm> |
| <function>get_bit</function> ( <parameter>bytes</parameter> <type>bytea</type>, |
| <parameter>n</parameter> <type>bigint</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Extracts <link linkend="functions-zerobased-note">n'th</link> bit |
| from binary string. |
| </para> |
| <para> |
| <literal>get_bit('\x1234567890'::bytea, 30)</literal> |
| <returnvalue>1</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>get_byte</primary> |
| </indexterm> |
| <function>get_byte</function> ( <parameter>bytes</parameter> <type>bytea</type>, |
| <parameter>n</parameter> <type>integer</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Extracts <link linkend="functions-zerobased-note">n'th</link> byte |
| from binary string. |
| </para> |
| <para> |
| <literal>get_byte('\x1234567890'::bytea, 4)</literal> |
| <returnvalue>144</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>length</primary> |
| </indexterm> |
| <indexterm> |
| <primary>binary string</primary> |
| <secondary>length</secondary> |
| </indexterm> |
| <indexterm> |
| <primary>length</primary> |
| <secondary sortas="binary string">of a binary string</secondary> |
| <see>binary strings, length</see> |
| </indexterm> |
| <function>length</function> ( <type>bytea</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns the number of bytes in the binary string. |
| </para> |
| <para> |
| <literal>length('\x1234567890'::bytea)</literal> |
| <returnvalue>5</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>length</function> ( <parameter>bytes</parameter> <type>bytea</type>, |
| <parameter>encoding</parameter> <type>name</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns the number of characters in the binary string, assuming |
| that it is text in the given <parameter>encoding</parameter>. |
| </para> |
| <para> |
| <literal>length('jose'::bytea, 'UTF8')</literal> |
| <returnvalue>4</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>ltrim</primary> |
| </indexterm> |
| <function>ltrim</function> ( <parameter>bytes</parameter> <type>bytea</type>, |
| <parameter>bytesremoved</parameter> <type>bytea</type> ) |
| <returnvalue>bytea</returnvalue> |
| </para> |
| <para> |
| Removes the longest string containing only bytes appearing in |
| <parameter>bytesremoved</parameter> from the start of |
| <parameter>bytes</parameter>. |
| </para> |
| <para> |
| <literal>ltrim('\x1234567890'::bytea, '\x9012'::bytea)</literal> |
| <returnvalue>\x34567890</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>md5</primary> |
| </indexterm> |
| <function>md5</function> ( <type>bytea</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Computes the MD5 <link linkend="functions-hash-note">hash</link> of |
| the binary string, with the result written in hexadecimal. |
| </para> |
| <para> |
| <literal>md5('Th\000omas'::bytea)</literal> |
| <returnvalue>8ab2d3c9689aaf18&zwsp;b4958c334c82d8b1</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>rtrim</primary> |
| </indexterm> |
| <function>rtrim</function> ( <parameter>bytes</parameter> <type>bytea</type>, |
| <parameter>bytesremoved</parameter> <type>bytea</type> ) |
| <returnvalue>bytea</returnvalue> |
| </para> |
| <para> |
| Removes the longest string containing only bytes appearing in |
| <parameter>bytesremoved</parameter> from the end of |
| <parameter>bytes</parameter>. |
| </para> |
| <para> |
| <literal>rtrim('\x1234567890'::bytea, '\x9012'::bytea)</literal> |
| <returnvalue>\x12345678</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>set_bit</primary> |
| </indexterm> |
| <function>set_bit</function> ( <parameter>bytes</parameter> <type>bytea</type>, |
| <parameter>n</parameter> <type>bigint</type>, |
| <parameter>newvalue</parameter> <type>integer</type> ) |
| <returnvalue>bytea</returnvalue> |
| </para> |
| <para> |
| Sets <link linkend="functions-zerobased-note">n'th</link> bit in |
| binary string to <parameter>newvalue</parameter>. |
| </para> |
| <para> |
| <literal>set_bit('\x1234567890'::bytea, 30, 0)</literal> |
| <returnvalue>\x1234563890</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>set_byte</primary> |
| </indexterm> |
| <function>set_byte</function> ( <parameter>bytes</parameter> <type>bytea</type>, |
| <parameter>n</parameter> <type>integer</type>, |
| <parameter>newvalue</parameter> <type>integer</type> ) |
| <returnvalue>bytea</returnvalue> |
| </para> |
| <para> |
| Sets <link linkend="functions-zerobased-note">n'th</link> byte in |
| binary string to <parameter>newvalue</parameter>. |
| </para> |
| <para> |
| <literal>set_byte('\x1234567890'::bytea, 4, 64)</literal> |
| <returnvalue>\x1234567840</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>sha224</primary> |
| </indexterm> |
| <function>sha224</function> ( <type>bytea</type> ) |
| <returnvalue>bytea</returnvalue> |
| </para> |
| <para> |
| Computes the SHA-224 <link linkend="functions-hash-note">hash</link> |
| of the binary string. |
| </para> |
| <para> |
| <literal>sha224('abc'::bytea)</literal> |
| <returnvalue>\x23097d223405d8228642a477bda2&zwsp;55b32aadbce4bda0b3f7e36c9da7</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>sha256</primary> |
| </indexterm> |
| <function>sha256</function> ( <type>bytea</type> ) |
| <returnvalue>bytea</returnvalue> |
| </para> |
| <para> |
| Computes the SHA-256 <link linkend="functions-hash-note">hash</link> |
| of the binary string. |
| </para> |
| <para> |
| <literal>sha256('abc'::bytea)</literal> |
| <returnvalue>\xba7816bf8f01cfea414140de5dae2223&zwsp;b00361a396177a9cb410ff61f20015ad</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>sha384</primary> |
| </indexterm> |
| <function>sha384</function> ( <type>bytea</type> ) |
| <returnvalue>bytea</returnvalue> |
| </para> |
| <para> |
| Computes the SHA-384 <link linkend="functions-hash-note">hash</link> |
| of the binary string. |
| </para> |
| <para> |
| <literal>sha384('abc'::bytea)</literal> |
| <returnvalue>\xcb00753f45a35e8bb5a03d699ac65007&zwsp;272c32ab0eded1631a8b605a43ff5bed&zwsp;8086072ba1e7cc2358baeca134c825a7</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>sha512</primary> |
| </indexterm> |
| <function>sha512</function> ( <type>bytea</type> ) |
| <returnvalue>bytea</returnvalue> |
| </para> |
| <para> |
| Computes the SHA-512 <link linkend="functions-hash-note">hash</link> |
| of the binary string. |
| </para> |
| <para> |
| <literal>sha512('abc'::bytea)</literal> |
| <returnvalue>\xddaf35a193617abacc417349ae204131&zwsp;12e6fa4e89a97ea20a9eeee64b55d39a&zwsp;2192992a274fc1a836ba3c23a3feebbd&zwsp;454d4423643ce80e2a9ac94fa54ca49f</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>substr</primary> |
| </indexterm> |
| <function>substr</function> ( <parameter>bytes</parameter> <type>bytea</type>, <parameter>start</parameter> <type>integer</type> <optional>, <parameter>count</parameter> <type>integer</type> </optional> ) |
| <returnvalue>bytea</returnvalue> |
| </para> |
| <para> |
| Extracts the substring of <parameter>bytes</parameter> starting at |
| the <parameter>start</parameter>'th byte, |
| and extending for <parameter>count</parameter> bytes if that is |
| specified. (Same |
| as <literal>substring(<parameter>bytes</parameter> |
| from <parameter>start</parameter> |
| for <parameter>count</parameter>)</literal>.) |
| </para> |
| <para> |
| <literal>substr('\x1234567890'::bytea, 3, 2)</literal> |
| <returnvalue>\x5678</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para id="functions-zerobased-note"> |
| Functions <function>get_byte</function> and <function>set_byte</function> |
| number the first byte of a binary string as byte 0. |
| Functions <function>get_bit</function> and <function>set_bit</function> |
| number bits from the right within each byte; for example bit 0 is the least |
| significant bit of the first byte, and bit 15 is the most significant bit |
| of the second byte. |
| </para> |
| |
| <para id="functions-hash-note"> |
| For historical reasons, the function <function>md5</function> |
| returns a hex-encoded value of type <type>text</type> whereas the SHA-2 |
| functions return type <type>bytea</type>. Use the functions |
| <link linkend="function-encode"><function>encode</function></link> |
| and <link linkend="function-decode"><function>decode</function></link> to |
| convert between the two. For example write <literal>encode(sha256('abc'), |
| 'hex')</literal> to get a hex-encoded text representation, |
| or <literal>decode(md5('abc'), 'hex')</literal> to get |
| a <type>bytea</type> value. |
| </para> |
| |
| <para> |
| <indexterm> |
| <primary>character string</primary> |
| <secondary>converting to binary string</secondary> |
| </indexterm> |
| <indexterm> |
| <primary>binary string</primary> |
| <secondary>converting to character string</secondary> |
| </indexterm> |
| Functions for converting strings between different character sets |
| (encodings), and for representing arbitrary binary data in textual |
| form, are shown in |
| <xref linkend="functions-binarystring-conversions"/>. For these |
| functions, an argument or result of type <type>text</type> is expressed |
| in the database's default encoding, while arguments or results of |
| type <type>bytea</type> are in an encoding named by another argument. |
| </para> |
| |
| <table id="functions-binarystring-conversions"> |
| <title>Text/Binary String Conversion Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>convert</primary> |
| </indexterm> |
| <function>convert</function> ( <parameter>bytes</parameter> <type>bytea</type>, |
| <parameter>src_encoding</parameter> <type>name</type>, |
| <parameter>dest_encoding</parameter> <type>name</type> ) |
| <returnvalue>bytea</returnvalue> |
| </para> |
| <para> |
| Converts a binary string representing text in |
| encoding <parameter>src_encoding</parameter> |
| to a binary string in encoding <parameter>dest_encoding</parameter> |
| (see <xref linkend="multibyte-conversions-supported"/> for |
| available conversions). |
| </para> |
| <para> |
| <literal>convert('text_in_utf8', 'UTF8', 'LATIN1')</literal> |
| <returnvalue>\x746578745f696e5f75746638</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>convert_from</primary> |
| </indexterm> |
| <function>convert_from</function> ( <parameter>bytes</parameter> <type>bytea</type>, |
| <parameter>src_encoding</parameter> <type>name</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Converts a binary string representing text in |
| encoding <parameter>src_encoding</parameter> |
| to <type>text</type> in the database encoding |
| (see <xref linkend="multibyte-conversions-supported"/> for |
| available conversions). |
| </para> |
| <para> |
| <literal>convert_from('text_in_utf8', 'UTF8')</literal> |
| <returnvalue>text_in_utf8</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>convert_to</primary> |
| </indexterm> |
| <function>convert_to</function> ( <parameter>string</parameter> <type>text</type>, |
| <parameter>dest_encoding</parameter> <type>name</type> ) |
| <returnvalue>bytea</returnvalue> |
| </para> |
| <para> |
| Converts a <type>text</type> string (in the database encoding) to a |
| binary string encoded in encoding <parameter>dest_encoding</parameter> |
| (see <xref linkend="multibyte-conversions-supported"/> for |
| available conversions). |
| </para> |
| <para> |
| <literal>convert_to('some_text', 'UTF8')</literal> |
| <returnvalue>\x736f6d655f74657874</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm id="function-encode"> |
| <primary>encode</primary> |
| </indexterm> |
| <function>encode</function> ( <parameter>bytes</parameter> <type>bytea</type>, |
| <parameter>format</parameter> <type>text</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Encodes binary data into a textual representation; supported |
| <parameter>format</parameter> values are: |
| <link linkend="encode-format-base64"><literal>base64</literal></link>, |
| <link linkend="encode-format-escape"><literal>escape</literal></link>, |
| <link linkend="encode-format-hex"><literal>hex</literal></link>. |
| </para> |
| <para> |
| <literal>encode('123\000\001', 'base64')</literal> |
| <returnvalue>MTIzAAE=</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm id="function-decode"> |
| <primary>decode</primary> |
| </indexterm> |
| <function>decode</function> ( <parameter>string</parameter> <type>text</type>, |
| <parameter>format</parameter> <type>text</type> ) |
| <returnvalue>bytea</returnvalue> |
| </para> |
| <para> |
| Decodes binary data from a textual representation; supported |
| <parameter>format</parameter> values are the same as |
| for <function>encode</function>. |
| </para> |
| <para> |
| <literal>decode('MTIzAAE=', 'base64')</literal> |
| <returnvalue>\x3132330001</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| The <function>encode</function> and <function>decode</function> |
| functions support the following textual formats: |
| |
| <variablelist> |
| <varlistentry id="encode-format-base64"> |
| <term>base64 |
| <indexterm> |
| <primary>base64 format</primary> |
| </indexterm></term> |
| <listitem> |
| <para> |
| The <literal>base64</literal> format is that |
| of <ulink url="https://tools.ietf.org/html/rfc2045#section-6.8">RFC |
| 2045 Section 6.8</ulink>. As per the <acronym>RFC</acronym>, encoded lines are |
| broken at 76 characters. However instead of the MIME CRLF |
| end-of-line marker, only a newline is used for end-of-line. |
| The <function>decode</function> function ignores carriage-return, |
| newline, space, and tab characters. Otherwise, an error is |
| raised when <function>decode</function> is supplied invalid |
| base64 data — including when trailing padding is incorrect. |
| </para> |
| </listitem> |
| </varlistentry> |
| |
| <varlistentry id="encode-format-escape"> |
| <term>escape |
| <indexterm> |
| <primary>escape format</primary> |
| </indexterm></term> |
| <listitem> |
| <para> |
| The <literal>escape</literal> format converts zero bytes and |
| bytes with the high bit set into octal escape sequences |
| (<literal>\</literal><replaceable>nnn</replaceable>), and it doubles |
| backslashes. Other byte values are represented literally. |
| The <function>decode</function> function will raise an error if a |
| backslash is not followed by either a second backslash or three |
| octal digits; it accepts other byte values unchanged. |
| </para> |
| </listitem> |
| </varlistentry> |
| |
| <varlistentry id="encode-format-hex"> |
| <term>hex |
| <indexterm> |
| <primary>hex format</primary> |
| </indexterm></term> |
| <listitem> |
| <para> |
| The <literal>hex</literal> format represents each 4 bits of |
| data as one hexadecimal digit, <literal>0</literal> |
| through <literal>f</literal>, writing the higher-order digit of |
| each byte first. The <function>encode</function> function outputs |
| the <literal>a</literal>-<literal>f</literal> hex digits in lower |
| case. Because the smallest unit of data is 8 bits, there are |
| always an even number of characters returned |
| by <function>encode</function>. |
| The <function>decode</function> function |
| accepts the <literal>a</literal>-<literal>f</literal> characters in |
| either upper or lower case. An error is raised |
| when <function>decode</function> is given invalid hex data |
| — including when given an odd number of characters. |
| </para> |
| </listitem> |
| </varlistentry> |
| </variablelist> |
| </para> |
| |
| <para> |
| See also the aggregate function <function>string_agg</function> in |
| <xref linkend="functions-aggregate"/> and the large object functions |
| in <xref linkend="lo-funcs"/>. |
| </para> |
| </sect1> |
| |
| |
| <sect1 id="functions-bitstring"> |
| <title>Bit String Functions and Operators</title> |
| |
| <indexterm zone="functions-bitstring"> |
| <primary>bit strings</primary> |
| <secondary>functions</secondary> |
| </indexterm> |
| |
| <para> |
| This section describes functions and operators for examining and |
| manipulating bit strings, that is values of the types |
| <type>bit</type> and <type>bit varying</type>. (While only |
| type <type>bit</type> is mentioned in these tables, values of |
| type <type>bit varying</type> can be used interchangeably.) |
| Bit strings support the usual comparison operators shown in |
| <xref linkend="functions-comparison-op-table"/>, as well as the |
| operators shown in <xref linkend="functions-bit-string-op-table"/>. |
| </para> |
| |
| <table id="functions-bit-string-op-table"> |
| <title>Bit String Operators</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Operator |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>bit</type> <literal>||</literal> <type>bit</type> |
| <returnvalue>bit</returnvalue> |
| </para> |
| <para> |
| Concatenation |
| </para> |
| <para> |
| <literal>B'10001' || B'011'</literal> |
| <returnvalue>10001011</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>bit</type> <literal>&</literal> <type>bit</type> |
| <returnvalue>bit</returnvalue> |
| </para> |
| <para> |
| Bitwise AND (inputs must be of equal length) |
| </para> |
| <para> |
| <literal>B'10001' & B'01101'</literal> |
| <returnvalue>00001</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>bit</type> <literal>|</literal> <type>bit</type> |
| <returnvalue>bit</returnvalue> |
| </para> |
| <para> |
| Bitwise OR (inputs must be of equal length) |
| </para> |
| <para> |
| <literal>B'10001' | B'01101'</literal> |
| <returnvalue>11101</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>bit</type> <literal>#</literal> <type>bit</type> |
| <returnvalue>bit</returnvalue> |
| </para> |
| <para> |
| Bitwise exclusive OR (inputs must be of equal length) |
| </para> |
| <para> |
| <literal>B'10001' # B'01101'</literal> |
| <returnvalue>11100</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <literal>~</literal> <type>bit</type> |
| <returnvalue>bit</returnvalue> |
| </para> |
| <para> |
| Bitwise NOT |
| </para> |
| <para> |
| <literal>~ B'10001'</literal> |
| <returnvalue>01110</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>bit</type> <literal><<</literal> <type>integer</type> |
| <returnvalue>bit</returnvalue> |
| </para> |
| <para> |
| Bitwise shift left |
| (string length is preserved) |
| </para> |
| <para> |
| <literal>B'10001' << 3</literal> |
| <returnvalue>01000</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>bit</type> <literal>>></literal> <type>integer</type> |
| <returnvalue>bit</returnvalue> |
| </para> |
| <para> |
| Bitwise shift right |
| (string length is preserved) |
| </para> |
| <para> |
| <literal>B'10001' >> 2</literal> |
| <returnvalue>00100</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| Some of the functions available for binary strings are also available |
| for bit strings, as shown in <xref linkend="functions-bit-string-table"/>. |
| </para> |
| |
| <table id="functions-bit-string-table"> |
| <title>Bit String Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>bit_count</primary> |
| </indexterm> |
| <function>bit_count</function> ( <type>bit</type> ) |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para> |
| Returns the number of bits set in the bit string (also known as |
| <quote>popcount</quote>). |
| </para> |
| <para> |
| <literal>bit_count(B'10111')</literal> |
| <returnvalue>4</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>bit_length</primary> |
| </indexterm> |
| <function>bit_length</function> ( <type>bit</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns number of bits in the bit string. |
| </para> |
| <para> |
| <literal>bit_length(B'10111')</literal> |
| <returnvalue>5</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>length</primary> |
| </indexterm> |
| <indexterm> |
| <primary>bit string</primary> |
| <secondary>length</secondary> |
| </indexterm> |
| <function>length</function> ( <type>bit</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns number of bits in the bit string. |
| </para> |
| <para> |
| <literal>length(B'10111')</literal> |
| <returnvalue>5</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>octet_length</primary> |
| </indexterm> |
| <function>octet_length</function> ( <type>bit</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns number of bytes in the bit string. |
| </para> |
| <para> |
| <literal>octet_length(B'1011111011')</literal> |
| <returnvalue>2</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>overlay</primary> |
| </indexterm> |
| <function>overlay</function> ( <parameter>bits</parameter> <type>bit</type> <literal>PLACING</literal> <parameter>newsubstring</parameter> <type>bit</type> <literal>FROM</literal> <parameter>start</parameter> <type>integer</type> <optional> <literal>FOR</literal> <parameter>count</parameter> <type>integer</type> </optional> ) |
| <returnvalue>bit</returnvalue> |
| </para> |
| <para> |
| Replaces the substring of <parameter>bits</parameter> that starts at |
| the <parameter>start</parameter>'th bit and extends |
| for <parameter>count</parameter> bits |
| with <parameter>newsubstring</parameter>. |
| If <parameter>count</parameter> is omitted, it defaults to the length |
| of <parameter>newsubstring</parameter>. |
| </para> |
| <para> |
| <literal>overlay(B'01010101010101010' placing B'11111' from 2 for 3)</literal> |
| <returnvalue>0111110101010101010</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>position</primary> |
| </indexterm> |
| <function>position</function> ( <parameter>substring</parameter> <type>bit</type> <literal>IN</literal> <parameter>bits</parameter> <type>bit</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns first starting index of the specified <parameter>substring</parameter> |
| within <parameter>bits</parameter>, or zero if it's not present. |
| </para> |
| <para> |
| <literal>position(B'010' in B'000001101011')</literal> |
| <returnvalue>8</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>substring</primary> |
| </indexterm> |
| <function>substring</function> ( <parameter>bits</parameter> <type>bit</type> <optional> <literal>FROM</literal> <parameter>start</parameter> <type>integer</type> </optional> <optional> <literal>FOR</literal> <parameter>count</parameter> <type>integer</type> </optional> ) |
| <returnvalue>bit</returnvalue> |
| </para> |
| <para> |
| Extracts the substring of <parameter>bits</parameter> starting at |
| the <parameter>start</parameter>'th bit if that is specified, |
| and stopping after <parameter>count</parameter> bits if that is |
| specified. Provide at least one of <parameter>start</parameter> |
| and <parameter>count</parameter>. |
| </para> |
| <para> |
| <literal>substring(B'110010111111' from 3 for 2)</literal> |
| <returnvalue>00</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>get_bit</primary> |
| </indexterm> |
| <function>get_bit</function> ( <parameter>bits</parameter> <type>bit</type>, |
| <parameter>n</parameter> <type>integer</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Extracts <parameter>n</parameter>'th bit |
| from bit string; the first (leftmost) bit is bit 0. |
| </para> |
| <para> |
| <literal>get_bit(B'101010101010101010', 6)</literal> |
| <returnvalue>1</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>set_bit</primary> |
| </indexterm> |
| <function>set_bit</function> ( <parameter>bits</parameter> <type>bit</type>, |
| <parameter>n</parameter> <type>integer</type>, |
| <parameter>newvalue</parameter> <type>integer</type> ) |
| <returnvalue>bit</returnvalue> |
| </para> |
| <para> |
| Sets <parameter>n</parameter>'th bit in |
| bit string to <parameter>newvalue</parameter>; |
| the first (leftmost) bit is bit 0. |
| </para> |
| <para> |
| <literal>set_bit(B'101010101010101010', 6, 0)</literal> |
| <returnvalue>101010001010101010</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| In addition, it is possible to cast integral values to and from type |
| <type>bit</type>. |
| Casting an integer to <type>bit(n)</type> copies the rightmost |
| <literal>n</literal> bits. Casting an integer to a bit string width wider |
| than the integer itself will sign-extend on the left. |
| Some examples: |
| <programlisting> |
| 44::bit(10) <lineannotation>0000101100</lineannotation> |
| 44::bit(3) <lineannotation>100</lineannotation> |
| cast(-44 as bit(12)) <lineannotation>111111010100</lineannotation> |
| '1110'::bit(4)::integer <lineannotation>14</lineannotation> |
| </programlisting> |
| Note that casting to just <quote>bit</quote> means casting to |
| <literal>bit(1)</literal>, and so will deliver only the least significant |
| bit of the integer. |
| </para> |
| </sect1> |
| |
| |
| <sect1 id="functions-matching"> |
| <title>Pattern Matching</title> |
| |
| <indexterm zone="functions-matching"> |
| <primary>pattern matching</primary> |
| </indexterm> |
| |
| <para> |
| There are three separate approaches to pattern matching provided |
| by <productname>PostgreSQL</productname>: the traditional |
| <acronym>SQL</acronym> <function>LIKE</function> operator, the |
| more recent <function>SIMILAR TO</function> operator (added in |
| SQL:1999), and <acronym>POSIX</acronym>-style regular |
| expressions. Aside from the basic <quote>does this string match |
| this pattern?</quote> operators, functions are available to extract |
| or replace matching substrings and to split a string at matching |
| locations. |
| </para> |
| |
| <tip> |
| <para> |
| If you have pattern matching needs that go beyond this, |
| consider writing a user-defined function in Perl or Tcl. |
| </para> |
| </tip> |
| |
| <caution> |
| <para> |
| While most regular-expression searches can be executed very quickly, |
| regular expressions can be contrived that take arbitrary amounts of |
| time and memory to process. Be wary of accepting regular-expression |
| search patterns from hostile sources. If you must do so, it is |
| advisable to impose a statement timeout. |
| </para> |
| |
| <para> |
| Searches using <function>SIMILAR TO</function> patterns have the same |
| security hazards, since <function>SIMILAR TO</function> provides many |
| of the same capabilities as <acronym>POSIX</acronym>-style regular |
| expressions. |
| </para> |
| |
| <para> |
| <function>LIKE</function> searches, being much simpler than the other |
| two options, are safer to use with possibly-hostile pattern sources. |
| </para> |
| </caution> |
| |
| <para> |
| The pattern matching operators of all three kinds do not support |
| nondeterministic collations. If required, apply a different collation to |
| the expression to work around this limitation. |
| </para> |
| |
| <sect2 id="functions-like"> |
| <title><function>LIKE</function></title> |
| |
| <indexterm> |
| <primary>LIKE</primary> |
| </indexterm> |
| |
| <synopsis> |
| <replaceable>string</replaceable> LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional> |
| <replaceable>string</replaceable> NOT LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional> |
| </synopsis> |
| |
| <para> |
| The <function>LIKE</function> expression returns true if the |
| <replaceable>string</replaceable> matches the supplied |
| <replaceable>pattern</replaceable>. (As |
| expected, the <function>NOT LIKE</function> expression returns |
| false if <function>LIKE</function> returns true, and vice versa. |
| An equivalent expression is |
| <literal>NOT (<replaceable>string</replaceable> LIKE |
| <replaceable>pattern</replaceable>)</literal>.) |
| </para> |
| |
| <para> |
| If <replaceable>pattern</replaceable> does not contain percent |
| signs or underscores, then the pattern only represents the string |
| itself; in that case <function>LIKE</function> acts like the |
| equals operator. An underscore (<literal>_</literal>) in |
| <replaceable>pattern</replaceable> stands for (matches) any single |
| character; a percent sign (<literal>%</literal>) matches any sequence |
| of zero or more characters. |
| </para> |
| |
| <para> |
| Some examples: |
| <programlisting> |
| 'abc' LIKE 'abc' <lineannotation>true</lineannotation> |
| 'abc' LIKE 'a%' <lineannotation>true</lineannotation> |
| 'abc' LIKE '_b_' <lineannotation>true</lineannotation> |
| 'abc' LIKE 'c' <lineannotation>false</lineannotation> |
| </programlisting> |
| </para> |
| |
| <para> |
| <function>LIKE</function> pattern matching always covers the entire |
| string. Therefore, if it's desired to match a sequence anywhere within |
| a string, the pattern must start and end with a percent sign. |
| </para> |
| |
| <para> |
| To match a literal underscore or percent sign without matching |
| other characters, the respective character in |
| <replaceable>pattern</replaceable> must be |
| preceded by the escape character. The default escape |
| character is the backslash but a different one can be selected by |
| using the <literal>ESCAPE</literal> clause. To match the escape |
| character itself, write two escape characters. |
| </para> |
| |
| <note> |
| <para> |
| If you have <xref linkend="guc-standard-conforming-strings"/> turned off, |
| any backslashes you write in literal string constants will need to be |
| doubled. See <xref linkend="sql-syntax-strings"/> for more information. |
| </para> |
| </note> |
| |
| <para> |
| It's also possible to select no escape character by writing |
| <literal>ESCAPE ''</literal>. This effectively disables the |
| escape mechanism, which makes it impossible to turn off the |
| special meaning of underscore and percent signs in the pattern. |
| </para> |
| |
| <para> |
| According to the SQL standard, omitting <literal>ESCAPE</literal> |
| means there is no escape character (rather than defaulting to a |
| backslash), and a zero-length <literal>ESCAPE</literal> value is |
| disallowed. <productname>PostgreSQL</productname>'s behavior in |
| this regard is therefore slightly nonstandard. |
| </para> |
| |
| <para> |
| The key word <token>ILIKE</token> can be used instead of |
| <token>LIKE</token> to make the match case-insensitive according |
| to the active locale. This is not in the <acronym>SQL</acronym> standard but is a |
| <productname>PostgreSQL</productname> extension. |
| </para> |
| |
| <para> |
| The operator <literal>~~</literal> is equivalent to |
| <function>LIKE</function>, and <literal>~~*</literal> corresponds to |
| <function>ILIKE</function>. There are also |
| <literal>!~~</literal> and <literal>!~~*</literal> operators that |
| represent <function>NOT LIKE</function> and <function>NOT |
| ILIKE</function>, respectively. All of these operators are |
| <productname>PostgreSQL</productname>-specific. You may see these |
| operator names in <command>EXPLAIN</command> output and similar |
| places, since the parser actually translates <function>LIKE</function> |
| et al. to these operators. |
| </para> |
| |
| <para> |
| The phrases <function>LIKE</function>, <function>ILIKE</function>, |
| <function>NOT LIKE</function>, and <function>NOT ILIKE</function> are |
| generally treated as operators |
| in <productname>PostgreSQL</productname> syntax; for example they can |
| be used in <replaceable>expression</replaceable> |
| <replaceable>operator</replaceable> ANY |
| (<replaceable>subquery</replaceable>) constructs, although |
| an <literal>ESCAPE</literal> clause cannot be included there. In some |
| obscure cases it may be necessary to use the underlying operator names |
| instead. |
| </para> |
| |
| <para> |
| Also see the prefix operator <literal>^@</literal> and corresponding |
| <function>starts_with</function> function, which are useful in cases |
| where simply matching the beginning of a string is needed. |
| </para> |
| </sect2> |
| |
| |
| <sect2 id="functions-similarto-regexp"> |
| <title><function>SIMILAR TO</function> Regular Expressions</title> |
| |
| <indexterm> |
| <primary>regular expression</primary> |
| <!-- <seealso>pattern matching</seealso> breaks index build --> |
| </indexterm> |
| |
| <indexterm> |
| <primary>SIMILAR TO</primary> |
| </indexterm> |
| <indexterm> |
| <primary>substring</primary> |
| </indexterm> |
| |
| <synopsis> |
| <replaceable>string</replaceable> SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional> |
| <replaceable>string</replaceable> NOT SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional> |
| </synopsis> |
| |
| <para> |
| The <function>SIMILAR TO</function> operator returns true or |
| false depending on whether its pattern matches the given string. |
| It is similar to <function>LIKE</function>, except that it |
| interprets the pattern using the SQL standard's definition of a |
| regular expression. SQL regular expressions are a curious cross |
| between <function>LIKE</function> notation and common (POSIX) regular |
| expression notation. |
| </para> |
| |
| <para> |
| Like <function>LIKE</function>, the <function>SIMILAR TO</function> |
| operator succeeds only if its pattern matches the entire string; |
| this is unlike common regular expression behavior where the pattern |
| can match any part of the string. |
| Also like |
| <function>LIKE</function>, <function>SIMILAR TO</function> uses |
| <literal>_</literal> and <literal>%</literal> as wildcard characters denoting |
| any single character and any string, respectively (these are |
| comparable to <literal>.</literal> and <literal>.*</literal> in POSIX regular |
| expressions). |
| </para> |
| |
| <para> |
| In addition to these facilities borrowed from <function>LIKE</function>, |
| <function>SIMILAR TO</function> supports these pattern-matching |
| metacharacters borrowed from POSIX regular expressions: |
| |
| <itemizedlist> |
| <listitem> |
| <para> |
| <literal>|</literal> denotes alternation (either of two alternatives). |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| <literal>*</literal> denotes repetition of the previous item zero |
| or more times. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| <literal>+</literal> denotes repetition of the previous item one |
| or more times. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| <literal>?</literal> denotes repetition of the previous item zero |
| or one time. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| <literal>{</literal><replaceable>m</replaceable><literal>}</literal> denotes repetition |
| of the previous item exactly <replaceable>m</replaceable> times. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| <literal>{</literal><replaceable>m</replaceable><literal>,}</literal> denotes repetition |
| of the previous item <replaceable>m</replaceable> or more times. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}</literal> |
| denotes repetition of the previous item at least <replaceable>m</replaceable> and |
| not more than <replaceable>n</replaceable> times. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| Parentheses <literal>()</literal> can be used to group items into |
| a single logical item. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| A bracket expression <literal>[...]</literal> specifies a character |
| class, just as in POSIX regular expressions. |
| </para> |
| </listitem> |
| </itemizedlist> |
| |
| Notice that the period (<literal>.</literal>) is not a metacharacter |
| for <function>SIMILAR TO</function>. |
| </para> |
| |
| <para> |
| As with <function>LIKE</function>, a backslash disables the special |
| meaning of any of these metacharacters. A different escape character |
| can be specified with <literal>ESCAPE</literal>, or the escape |
| capability can be disabled by writing <literal>ESCAPE ''</literal>. |
| </para> |
| |
| <para> |
| According to the SQL standard, omitting <literal>ESCAPE</literal> |
| means there is no escape character (rather than defaulting to a |
| backslash), and a zero-length <literal>ESCAPE</literal> value is |
| disallowed. <productname>PostgreSQL</productname>'s behavior in |
| this regard is therefore slightly nonstandard. |
| </para> |
| |
| <para> |
| Another nonstandard extension is that following the escape character |
| with a letter or digit provides access to the escape sequences |
| defined for POSIX regular expressions; see |
| <xref linkend="posix-character-entry-escapes-table"/>, |
| <xref linkend="posix-class-shorthand-escapes-table"/>, and |
| <xref linkend="posix-constraint-escapes-table"/> below. |
| </para> |
| |
| <para> |
| Some examples: |
| <programlisting> |
| 'abc' SIMILAR TO 'abc' <lineannotation>true</lineannotation> |
| 'abc' SIMILAR TO 'a' <lineannotation>false</lineannotation> |
| 'abc' SIMILAR TO '%(b|d)%' <lineannotation>true</lineannotation> |
| 'abc' SIMILAR TO '(b|c)%' <lineannotation>false</lineannotation> |
| '-abc-' SIMILAR TO '%\mabc\M%' <lineannotation>true</lineannotation> |
| 'xabcy' SIMILAR TO '%\mabc\M%' <lineannotation>false</lineannotation> |
| </programlisting> |
| </para> |
| |
| <para> |
| The <function>substring</function> function with three parameters |
| provides extraction of a substring that matches an SQL |
| regular expression pattern. The function can be written according |
| to standard SQL syntax: |
| <synopsis> |
| substring(<replaceable>string</replaceable> similar <replaceable>pattern</replaceable> escape <replaceable>escape-character</replaceable>) |
| </synopsis> |
| or using the now obsolete SQL:1999 syntax: |
| <synopsis> |
| substring(<replaceable>string</replaceable> from <replaceable>pattern</replaceable> for <replaceable>escape-character</replaceable>) |
| </synopsis> |
| or as a plain three-argument function: |
| <synopsis> |
| substring(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>, <replaceable>escape-character</replaceable>) |
| </synopsis> |
| As with <literal>SIMILAR TO</literal>, the |
| specified pattern must match the entire data string, or else the |
| function fails and returns null. To indicate the part of the |
| pattern for which the matching data sub-string is of interest, |
| the pattern should contain |
| two occurrences of the escape character followed by a double quote |
| (<literal>"</literal>). <!-- " font-lock sanity --> |
| The text matching the portion of the pattern |
| between these separators is returned when the match is successful. |
| </para> |
| |
| <para> |
| The escape-double-quote separators actually |
| divide <function>substring</function>'s pattern into three independent |
| regular expressions; for example, a vertical bar (<literal>|</literal>) |
| in any of the three sections affects only that section. Also, the first |
| and third of these regular expressions are defined to match the smallest |
| possible amount of text, not the largest, when there is any ambiguity |
| about how much of the data string matches which pattern. (In POSIX |
| parlance, the first and third regular expressions are forced to be |
| non-greedy.) |
| </para> |
| |
| <para> |
| As an extension to the SQL standard, <productname>PostgreSQL</productname> |
| allows there to be just one escape-double-quote separator, in which case |
| the third regular expression is taken as empty; or no separators, in which |
| case the first and third regular expressions are taken as empty. |
| </para> |
| |
| <para> |
| Some examples, with <literal>#"</literal> delimiting the return string: |
| <programlisting> |
| substring('foobar' similar '%#"o_b#"%' escape '#') <lineannotation>oob</lineannotation> |
| substring('foobar' similar '#"o_b#"%' escape '#') <lineannotation>NULL</lineannotation> |
| </programlisting> |
| </para> |
| </sect2> |
| |
| <sect2 id="functions-posix-regexp"> |
| <title><acronym>POSIX</acronym> Regular Expressions</title> |
| |
| <indexterm zone="functions-posix-regexp"> |
| <primary>regular expression</primary> |
| <seealso>pattern matching</seealso> |
| </indexterm> |
| <indexterm> |
| <primary>substring</primary> |
| </indexterm> |
| <indexterm> |
| <primary>regexp_replace</primary> |
| </indexterm> |
| <indexterm> |
| <primary>regexp_match</primary> |
| </indexterm> |
| <indexterm> |
| <primary>regexp_matches</primary> |
| </indexterm> |
| <indexterm> |
| <primary>regexp_split_to_table</primary> |
| </indexterm> |
| <indexterm> |
| <primary>regexp_split_to_array</primary> |
| </indexterm> |
| |
| <para> |
| <xref linkend="functions-posix-table"/> lists the available |
| operators for pattern matching using POSIX regular expressions. |
| </para> |
| |
| <table id="functions-posix-table"> |
| <title>Regular Expression Match Operators</title> |
| |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Operator |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>text</type> <literal>~</literal> <type>text</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| String matches regular expression, case sensitively |
| </para> |
| <para> |
| <literal>'thomas' ~ 't.*ma'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>text</type> <literal>~*</literal> <type>text</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| String matches regular expression, case insensitively |
| </para> |
| <para> |
| <literal>'thomas' ~* 'T.*ma'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>text</type> <literal>!~</literal> <type>text</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| String does not match regular expression, case sensitively |
| </para> |
| <para> |
| <literal>'thomas' !~ 't.*max'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>text</type> <literal>!~*</literal> <type>text</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| String does not match regular expression, case insensitively |
| </para> |
| <para> |
| <literal>'thomas' !~* 'T.*ma'</literal> |
| <returnvalue>f</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| <acronym>POSIX</acronym> regular expressions provide a more |
| powerful means for pattern matching than the <function>LIKE</function> and |
| <function>SIMILAR TO</function> operators. |
| Many Unix tools such as <command>egrep</command>, |
| <command>sed</command>, or <command>awk</command> use a pattern |
| matching language that is similar to the one described here. |
| </para> |
| |
| <para> |
| A regular expression is a character sequence that is an |
| abbreviated definition of a set of strings (a <firstterm>regular |
| set</firstterm>). 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 <function>LIKE</function>, pattern characters |
| match string characters exactly unless they are special characters |
| in the regular expression language — but regular expressions use |
| different special characters than <function>LIKE</function> does. |
| Unlike <function>LIKE</function> 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. |
| </para> |
| |
| <para> |
| Some examples: |
| <programlisting> |
| 'abcd' ~ 'bc' <lineannotation>true</lineannotation> |
| 'abcd' ~ 'a.c' <lineannotation>true — dot matches any character</lineannotation> |
| 'abcd' ~ 'a.*d' <lineannotation>true — <literal>*</literal> repeats the preceding pattern item</lineannotation> |
| 'abcd' ~ '(b|x)' <lineannotation>true — <literal>|</literal> means OR, parentheses group</lineannotation> |
| 'abcd' ~ '^a' <lineannotation>true — <literal>^</literal> anchors to start of string</lineannotation> |
| 'abcd' ~ '^(b|c)' <lineannotation>false — would match except for anchoring</lineannotation> |
| </programlisting> |
| </para> |
| |
| <para> |
| The <acronym>POSIX</acronym> pattern language is described in much |
| greater detail below. |
| </para> |
| |
| <para> |
| The <function>substring</function> function with two parameters, |
| <function>substring(<replaceable>string</replaceable> from |
| <replaceable>pattern</replaceable>)</function>, provides extraction of a |
| substring |
| that matches a POSIX regular expression pattern. It returns null if |
| there is no match, otherwise the first portion of the text that matched the |
| pattern. But if the pattern contains any parentheses, the portion |
| of the text that matched the first parenthesized subexpression (the |
| one whose left parenthesis comes first) is |
| returned. You can put parentheses around the whole expression |
| if you want to use parentheses within it without triggering this |
| exception. If you need parentheses in the pattern before the |
| subexpression you want to extract, see the non-capturing parentheses |
| described below. |
| </para> |
| |
| <para> |
| Some examples: |
| <programlisting> |
| substring('foobar' from 'o.b') <lineannotation>oob</lineannotation> |
| substring('foobar' from 'o(.)b') <lineannotation>o</lineannotation> |
| </programlisting> |
| </para> |
| |
| <para> |
| The <function>regexp_replace</function> function provides substitution of |
| new text for substrings that match POSIX regular expression patterns. |
| It has the syntax |
| <function>regexp_replace</function>(<replaceable>source</replaceable>, |
| <replaceable>pattern</replaceable>, <replaceable>replacement</replaceable> |
| <optional>, <replaceable>flags</replaceable> </optional>). |
| The <replaceable>source</replaceable> string is returned unchanged if |
| there is no match to the <replaceable>pattern</replaceable>. If there is a |
| match, the <replaceable>source</replaceable> string is returned with the |
| <replaceable>replacement</replaceable> string substituted for the matching |
| substring. The <replaceable>replacement</replaceable> string can contain |
| <literal>\</literal><replaceable>n</replaceable>, where <replaceable>n</replaceable> is 1 |
| through 9, to indicate that the source substring matching the |
| <replaceable>n</replaceable>'th parenthesized subexpression of the pattern should be |
| inserted, and it can contain <literal>\&</literal> to indicate that the |
| substring matching the entire pattern should be inserted. Write |
| <literal>\\</literal> if you need to put a literal backslash in the replacement |
| text. |
| The <replaceable>flags</replaceable> parameter is an optional text |
| string containing zero or more single-letter flags that change the |
| function's behavior. Flag <literal>i</literal> specifies case-insensitive |
| matching, while flag <literal>g</literal> specifies replacement of each matching |
| substring rather than only the first one. Supported flags (though |
| not <literal>g</literal>) are |
| described in <xref linkend="posix-embedded-options-table"/>. |
| </para> |
| |
| <para> |
| Some examples: |
| <programlisting> |
| regexp_replace('foobarbaz', 'b..', 'X') |
| <lineannotation>fooXbaz</lineannotation> |
| regexp_replace('foobarbaz', 'b..', 'X', 'g') |
| <lineannotation>fooXX</lineannotation> |
| regexp_replace('foobarbaz', 'b(..)', 'X\1Y', 'g') |
| <lineannotation>fooXarYXazY</lineannotation> |
| </programlisting> |
| </para> |
| |
| <para> |
| The <function>regexp_match</function> function returns a text array of |
| captured substring(s) resulting from the first match of a POSIX |
| regular expression pattern to a string. It has the syntax |
| <function>regexp_match</function>(<replaceable>string</replaceable>, |
| <replaceable>pattern</replaceable> <optional>, <replaceable>flags</replaceable> </optional>). |
| If there is no match, the result is <literal>NULL</literal>. |
| If a match is found, and the <replaceable>pattern</replaceable> contains no |
| parenthesized subexpressions, then the result is a single-element text |
| array containing the substring matching the whole pattern. |
| If a match is found, and the <replaceable>pattern</replaceable> contains |
| parenthesized subexpressions, then the result is a text array |
| whose <replaceable>n</replaceable>'th element is the substring matching |
| the <replaceable>n</replaceable>'th parenthesized subexpression of |
| the <replaceable>pattern</replaceable> (not counting <quote>non-capturing</quote> |
| parentheses; see below for details). |
| The <replaceable>flags</replaceable> parameter is an optional text string |
| containing zero or more single-letter flags that change the function's |
| behavior. Supported flags are described |
| in <xref linkend="posix-embedded-options-table"/>. |
| </para> |
| |
| <para> |
| Some examples: |
| <programlisting> |
| SELECT regexp_match('foobarbequebaz', 'bar.*que'); |
| regexp_match |
| -------------- |
| {barbeque} |
| (1 row) |
| |
| SELECT regexp_match('foobarbequebaz', '(bar)(beque)'); |
| regexp_match |
| -------------- |
| {bar,beque} |
| (1 row) |
| </programlisting> |
| In the common case where you just want the whole matching substring |
| or <literal>NULL</literal> for no match, write something like |
| <programlisting> |
| SELECT (regexp_match('foobarbequebaz', 'bar.*que'))[1]; |
| regexp_match |
| -------------- |
| barbeque |
| (1 row) |
| </programlisting> |
| </para> |
| |
| <para> |
| The <function>regexp_matches</function> function returns a set of text arrays |
| of captured substring(s) resulting from matching a POSIX regular |
| expression pattern to a string. It has the same syntax as |
| <function>regexp_match</function>. |
| This function returns no rows if there is no match, one row if there is |
| a match and the <literal>g</literal> flag is not given, or <replaceable>N</replaceable> |
| rows if there are <replaceable>N</replaceable> matches and the <literal>g</literal> flag |
| is given. Each returned row is a text array containing the whole |
| matched substring or the substrings matching parenthesized |
| subexpressions of the <replaceable>pattern</replaceable>, just as described above |
| for <function>regexp_match</function>. |
| <function>regexp_matches</function> accepts all the flags shown |
| in <xref linkend="posix-embedded-options-table"/>, plus |
| the <literal>g</literal> flag which commands it to return all matches, not |
| just the first one. |
| </para> |
| |
| <para> |
| Some examples: |
| <programlisting> |
| SELECT regexp_matches('foo', 'not there'); |
| regexp_matches |
| ---------------- |
| (0 rows) |
| |
| SELECT regexp_matches('foobarbequebazilbarfbonk', '(b[^b]+)(b[^b]+)', 'g'); |
| regexp_matches |
| ---------------- |
| {bar,beque} |
| {bazil,barf} |
| (2 rows) |
| </programlisting> |
| </para> |
| |
| <tip> |
| <para> |
| In most cases <function>regexp_matches()</function> should be used with |
| the <literal>g</literal> flag, since if you only want the first match, it's |
| easier and more efficient to use <function>regexp_match()</function>. |
| However, <function>regexp_match()</function> only exists |
| in <productname>PostgreSQL</productname> version 10 and up. When working in older |
| versions, a common trick is to place a <function>regexp_matches()</function> |
| call in a sub-select, for example: |
| <programlisting> |
| SELECT col1, (SELECT regexp_matches(col2, '(bar)(beque)')) FROM tab; |
| </programlisting> |
| This produces a text array if there's a match, or <literal>NULL</literal> if |
| not, the same as <function>regexp_match()</function> would do. Without the |
| sub-select, this query would produce no output at all for table rows |
| without a match, which is typically not the desired behavior. |
| </para> |
| </tip> |
| |
| <para> |
| The <function>regexp_split_to_table</function> function splits a string using a POSIX |
| regular expression pattern as a delimiter. It has the syntax |
| <function>regexp_split_to_table</function>(<replaceable>string</replaceable>, <replaceable>pattern</replaceable> |
| <optional>, <replaceable>flags</replaceable> </optional>). |
| If there is no match to the <replaceable>pattern</replaceable>, the function returns the |
| <replaceable>string</replaceable>. If there is at least one match, for each match it returns |
| the text from the end of the last match (or the beginning of the string) |
| to the beginning of the match. When there are no more matches, it |
| returns the text from the end of the last match to the end of the string. |
| The <replaceable>flags</replaceable> parameter is an optional text string containing |
| zero or more single-letter flags that change the function's behavior. |
| <function>regexp_split_to_table</function> supports the flags described in |
| <xref linkend="posix-embedded-options-table"/>. |
| </para> |
| |
| <para> |
| The <function>regexp_split_to_array</function> function behaves the same as |
| <function>regexp_split_to_table</function>, except that <function>regexp_split_to_array</function> |
| returns its result as an array of <type>text</type>. It has the syntax |
| <function>regexp_split_to_array</function>(<replaceable>string</replaceable>, <replaceable>pattern</replaceable> |
| <optional>, <replaceable>flags</replaceable> </optional>). |
| The parameters are the same as for <function>regexp_split_to_table</function>. |
| </para> |
| |
| <para> |
| Some examples: |
| <programlisting> |
| |
| SELECT foo FROM regexp_split_to_table('the quick brown fox jumps over the lazy dog', '\s+') AS foo; |
| foo |
| ------- |
| the |
| quick |
| brown |
| fox |
| jumps |
| over |
| the |
| lazy |
| dog |
| (9 rows) |
| |
| SELECT regexp_split_to_array('the quick brown fox jumps over the lazy dog', '\s+'); |
| regexp_split_to_array |
| ----------------------------------------------- |
| {the,quick,brown,fox,jumps,over,the,lazy,dog} |
| (1 row) |
| |
| SELECT foo FROM regexp_split_to_table('the quick brown fox', '\s*') AS foo; |
| foo |
| ----- |
| t |
| h |
| e |
| q |
| u |
| i |
| c |
| k |
| b |
| r |
| o |
| w |
| n |
| f |
| o |
| x |
| (16 rows) |
| </programlisting> |
| </para> |
| |
| <para> |
| As the last example demonstrates, the regexp split functions ignore |
| zero-length matches that occur at the start or end of the string |
| or immediately after a previous match. This is contrary to the strict |
| definition of regexp matching that is implemented by |
| <function>regexp_match</function> and |
| <function>regexp_matches</function>, but is usually the most convenient behavior |
| in practice. Other software systems such as Perl use similar definitions. |
| </para> |
| |
| <!-- derived from the re_syntax.n man page --> |
| |
| <sect3 id="posix-syntax-details"> |
| <title>Regular Expression Details</title> |
| |
| <para> |
| <productname>PostgreSQL</productname>'s regular expressions are implemented |
| using a software package written by Henry Spencer. Much of |
| the description of regular expressions below is copied verbatim from his |
| manual. |
| </para> |
| |
| <para> |
| Regular expressions (<acronym>RE</acronym>s), as defined in |
| <acronym>POSIX</acronym> 1003.2, come in two forms: |
| <firstterm>extended</firstterm> <acronym>RE</acronym>s or <acronym>ERE</acronym>s |
| (roughly those of <command>egrep</command>), and |
| <firstterm>basic</firstterm> <acronym>RE</acronym>s or <acronym>BRE</acronym>s |
| (roughly those of <command>ed</command>). |
| <productname>PostgreSQL</productname> supports both forms, and |
| also implements some extensions |
| that are not in the POSIX standard, but have become widely used |
| due to their availability in programming languages such as Perl and Tcl. |
| <acronym>RE</acronym>s using these non-POSIX extensions are called |
| <firstterm>advanced</firstterm> <acronym>RE</acronym>s or <acronym>ARE</acronym>s |
| in this documentation. AREs are almost an exact superset of EREs, |
| but BREs have several notational incompatibilities (as well as being |
| much more limited). |
| We first describe the ARE and ERE forms, noting features that apply |
| only to AREs, and then describe how BREs differ. |
| </para> |
| |
| <note> |
| <para> |
| <productname>PostgreSQL</productname> always initially presumes that a regular |
| expression follows the ARE rules. However, the more limited ERE or |
| BRE rules can be chosen by prepending an <firstterm>embedded option</firstterm> |
| to the RE pattern, as described in <xref linkend="posix-metasyntax"/>. |
| This can be useful for compatibility with applications that expect |
| exactly the <acronym>POSIX</acronym> 1003.2 rules. |
| </para> |
| </note> |
| |
| <para> |
| A regular expression is defined as one or more |
| <firstterm>branches</firstterm>, separated by |
| <literal>|</literal>. It matches anything that matches one of the |
| branches. |
| </para> |
| |
| <para> |
| A branch is zero or more <firstterm>quantified atoms</firstterm> or |
| <firstterm>constraints</firstterm>, concatenated. |
| It matches a match for the first, followed by a match for the second, etc; |
| an empty branch matches the empty string. |
| </para> |
| |
| <para> |
| A quantified atom is an <firstterm>atom</firstterm> possibly followed |
| by a single <firstterm>quantifier</firstterm>. |
| Without a quantifier, it matches a match for the atom. |
| With a quantifier, it can match some number of matches of the atom. |
| An <firstterm>atom</firstterm> can be any of the possibilities |
| shown in <xref linkend="posix-atoms-table"/>. |
| The possible quantifiers and their meanings are shown in |
| <xref linkend="posix-quantifiers-table"/>. |
| </para> |
| |
| <para> |
| A <firstterm>constraint</firstterm> matches an empty string, but matches only when |
| specific conditions are met. A constraint can be used where an atom |
| could be used, except it cannot be followed by a quantifier. |
| The simple constraints are shown in |
| <xref linkend="posix-constraints-table"/>; |
| some more constraints are described later. |
| </para> |
| |
| |
| <table id="posix-atoms-table"> |
| <title>Regular Expression Atoms</title> |
| |
| <tgroup cols="2"> |
| <thead> |
| <row> |
| <entry>Atom</entry> |
| <entry>Description</entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry> <literal>(</literal><replaceable>re</replaceable><literal>)</literal> </entry> |
| <entry> (where <replaceable>re</replaceable> is any regular expression) |
| matches a match for |
| <replaceable>re</replaceable>, with the match noted for possible reporting </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>(?:</literal><replaceable>re</replaceable><literal>)</literal> </entry> |
| <entry> as above, but the match is not noted for reporting |
| (a <quote>non-capturing</quote> set of parentheses) |
| (AREs only) </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>.</literal> </entry> |
| <entry> matches any single character </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>[</literal><replaceable>chars</replaceable><literal>]</literal> </entry> |
| <entry> a <firstterm>bracket expression</firstterm>, |
| matching any one of the <replaceable>chars</replaceable> (see |
| <xref linkend="posix-bracket-expressions"/> for more detail) </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\</literal><replaceable>k</replaceable> </entry> |
| <entry> (where <replaceable>k</replaceable> is a non-alphanumeric character) |
| matches that character taken as an ordinary character, |
| e.g., <literal>\\</literal> matches a backslash character </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\</literal><replaceable>c</replaceable> </entry> |
| <entry> where <replaceable>c</replaceable> is alphanumeric |
| (possibly followed by other characters) |
| is an <firstterm>escape</firstterm>, see <xref linkend="posix-escape-sequences"/> |
| (AREs only; in EREs and BREs, this matches <replaceable>c</replaceable>) </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>{</literal> </entry> |
| <entry> when followed by a character other than a digit, |
| matches the left-brace character <literal>{</literal>; |
| when followed by a digit, it is the beginning of a |
| <replaceable>bound</replaceable> (see below) </entry> |
| </row> |
| |
| <row> |
| <entry> <replaceable>x</replaceable> </entry> |
| <entry> where <replaceable>x</replaceable> is a single character with no other |
| significance, matches that character </entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| An RE cannot end with a backslash (<literal>\</literal>). |
| </para> |
| |
| <note> |
| <para> |
| If you have <xref linkend="guc-standard-conforming-strings"/> turned off, |
| any backslashes you write in literal string constants will need to be |
| doubled. See <xref linkend="sql-syntax-strings"/> for more information. |
| </para> |
| </note> |
| |
| <table id="posix-quantifiers-table"> |
| <title>Regular Expression Quantifiers</title> |
| |
| <tgroup cols="2"> |
| <thead> |
| <row> |
| <entry>Quantifier</entry> |
| <entry>Matches</entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry> <literal>*</literal> </entry> |
| <entry> a sequence of 0 or more matches of the atom </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>+</literal> </entry> |
| <entry> a sequence of 1 or more matches of the atom </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>?</literal> </entry> |
| <entry> a sequence of 0 or 1 matches of the atom </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>{</literal><replaceable>m</replaceable><literal>}</literal> </entry> |
| <entry> a sequence of exactly <replaceable>m</replaceable> matches of the atom </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>{</literal><replaceable>m</replaceable><literal>,}</literal> </entry> |
| <entry> a sequence of <replaceable>m</replaceable> or more matches of the atom </entry> |
| </row> |
| |
| <row> |
| <entry> |
| <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}</literal> </entry> |
| <entry> a sequence of <replaceable>m</replaceable> through <replaceable>n</replaceable> |
| (inclusive) matches of the atom; <replaceable>m</replaceable> cannot exceed |
| <replaceable>n</replaceable> </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>*?</literal> </entry> |
| <entry> non-greedy version of <literal>*</literal> </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>+?</literal> </entry> |
| <entry> non-greedy version of <literal>+</literal> </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>??</literal> </entry> |
| <entry> non-greedy version of <literal>?</literal> </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>{</literal><replaceable>m</replaceable><literal>}?</literal> </entry> |
| <entry> non-greedy version of <literal>{</literal><replaceable>m</replaceable><literal>}</literal> </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>{</literal><replaceable>m</replaceable><literal>,}?</literal> </entry> |
| <entry> non-greedy version of <literal>{</literal><replaceable>m</replaceable><literal>,}</literal> </entry> |
| </row> |
| |
| <row> |
| <entry> |
| <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}?</literal> </entry> |
| <entry> non-greedy version of <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}</literal> </entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| The forms using <literal>{</literal><replaceable>...</replaceable><literal>}</literal> |
| are known as <firstterm>bounds</firstterm>. |
| The numbers <replaceable>m</replaceable> and <replaceable>n</replaceable> within a bound are |
| unsigned decimal integers with permissible values from 0 to 255 inclusive. |
| </para> |
| |
| <para> |
| <firstterm>Non-greedy</firstterm> quantifiers (available in AREs only) match the |
| same possibilities as their corresponding normal (<firstterm>greedy</firstterm>) |
| counterparts, but prefer the smallest number rather than the largest |
| number of matches. |
| See <xref linkend="posix-matching-rules"/> for more detail. |
| </para> |
| |
| <note> |
| <para> |
| A quantifier cannot immediately follow another quantifier, e.g., |
| <literal>**</literal> is invalid. |
| A quantifier cannot |
| begin an expression or subexpression or follow |
| <literal>^</literal> or <literal>|</literal>. |
| </para> |
| </note> |
| |
| <table id="posix-constraints-table"> |
| <title>Regular Expression Constraints</title> |
| |
| <tgroup cols="2"> |
| <thead> |
| <row> |
| <entry>Constraint</entry> |
| <entry>Description</entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry> <literal>^</literal> </entry> |
| <entry> matches at the beginning of the string </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>$</literal> </entry> |
| <entry> matches at the end of the string </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>(?=</literal><replaceable>re</replaceable><literal>)</literal> </entry> |
| <entry> <firstterm>positive lookahead</firstterm> matches at any point |
| where a substring matching <replaceable>re</replaceable> begins |
| (AREs only) </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>(?!</literal><replaceable>re</replaceable><literal>)</literal> </entry> |
| <entry> <firstterm>negative lookahead</firstterm> matches at any point |
| where no substring matching <replaceable>re</replaceable> begins |
| (AREs only) </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>(?<=</literal><replaceable>re</replaceable><literal>)</literal> </entry> |
| <entry> <firstterm>positive lookbehind</firstterm> matches at any point |
| where a substring matching <replaceable>re</replaceable> ends |
| (AREs only) </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>(?<!</literal><replaceable>re</replaceable><literal>)</literal> </entry> |
| <entry> <firstterm>negative lookbehind</firstterm> matches at any point |
| where no substring matching <replaceable>re</replaceable> ends |
| (AREs only) </entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| Lookahead and lookbehind constraints cannot contain <firstterm>back |
| references</firstterm> (see <xref linkend="posix-escape-sequences"/>), |
| and all parentheses within them are considered non-capturing. |
| </para> |
| </sect3> |
| |
| <sect3 id="posix-bracket-expressions"> |
| <title>Bracket Expressions</title> |
| |
| <para> |
| A <firstterm>bracket expression</firstterm> is a list of |
| characters enclosed in <literal>[]</literal>. It normally matches |
| any single character from the list (but see below). If the list |
| begins with <literal>^</literal>, it matches any single character |
| <emphasis>not</emphasis> from the rest of the list. |
| If two characters |
| in the list are separated by <literal>-</literal>, this is |
| shorthand for the full range of characters between those two |
| (inclusive) in the collating sequence, |
| e.g., <literal>[0-9]</literal> in <acronym>ASCII</acronym> matches |
| any decimal digit. It is illegal for two ranges to share an |
| endpoint, e.g., <literal>a-c-e</literal>. Ranges are very |
| collating-sequence-dependent, so portable programs should avoid |
| relying on them. |
| </para> |
| |
| <para> |
| To include a literal <literal>]</literal> in the list, make it the |
| first character (after <literal>^</literal>, if that is used). To |
| include a literal <literal>-</literal>, make it the first or last |
| character, or the second endpoint of a range. To use a literal |
| <literal>-</literal> as the first endpoint of a range, enclose it |
| in <literal>[.</literal> and <literal>.]</literal> to make it a |
| collating element (see below). With the exception of these characters, |
| some combinations using <literal>[</literal> |
| (see next paragraphs), and escapes (AREs only), all other special |
| characters lose their special significance within a bracket expression. |
| In particular, <literal>\</literal> is not special when following |
| ERE or BRE rules, though it is special (as introducing an escape) |
| in AREs. |
| </para> |
| |
| <para> |
| Within a bracket expression, a collating element (a character, a |
| multiple-character sequence that collates as if it were a single |
| character, or a collating-sequence name for either) enclosed in |
| <literal>[.</literal> and <literal>.]</literal> stands for the |
| sequence of characters of that collating element. The sequence is |
| treated as a single element of the bracket expression's list. This |
| allows a bracket |
| expression containing a multiple-character collating element to |
| match more than one character, e.g., if the collating sequence |
| includes a <literal>ch</literal> collating element, then the RE |
| <literal>[[.ch.]]*c</literal> matches the first five characters of |
| <literal>chchcc</literal>. |
| </para> |
| |
| <note> |
| <para> |
| <productname>PostgreSQL</productname> currently does not support multi-character collating |
| elements. This information describes possible future behavior. |
| </para> |
| </note> |
| |
| <para> |
| Within a bracket expression, a collating element enclosed in |
| <literal>[=</literal> and <literal>=]</literal> is an <firstterm>equivalence |
| class</firstterm>, standing for the sequences of characters of all collating |
| elements equivalent to that one, including itself. (If there are |
| no other equivalent collating elements, the treatment is as if the |
| enclosing delimiters were <literal>[.</literal> and |
| <literal>.]</literal>.) For example, if <literal>o</literal> and |
| <literal>^</literal> are the members of an equivalence class, then |
| <literal>[[=o=]]</literal>, <literal>[[=^=]]</literal>, and |
| <literal>[o^]</literal> are all synonymous. An equivalence class |
| cannot be an endpoint of a range. |
| </para> |
| |
| <para> |
| Within a bracket expression, the name of a character class |
| enclosed in <literal>[:</literal> and <literal>:]</literal> stands |
| for the list of all characters belonging to that class. A character |
| class cannot be used as an endpoint of a range. |
| The <acronym>POSIX</acronym> standard defines these character class |
| names: |
| <literal>alnum</literal> (letters and numeric digits), |
| <literal>alpha</literal> (letters), |
| <literal>blank</literal> (space and tab), |
| <literal>cntrl</literal> (control characters), |
| <literal>digit</literal> (numeric digits), |
| <literal>graph</literal> (printable characters except space), |
| <literal>lower</literal> (lower-case letters), |
| <literal>print</literal> (printable characters including space), |
| <literal>punct</literal> (punctuation), |
| <literal>space</literal> (any white space), |
| <literal>upper</literal> (upper-case letters), |
| and <literal>xdigit</literal> (hexadecimal digits). |
| The behavior of these standard character classes is generally |
| consistent across platforms for characters in the 7-bit ASCII set. |
| Whether a given non-ASCII character is considered to belong to one |
| of these classes depends on the <firstterm>collation</firstterm> |
| that is used for the regular-expression function or operator |
| (see <xref linkend="collation"/>), or by default on the |
| database's <envar>LC_CTYPE</envar> locale setting (see |
| <xref linkend="locale"/>). The classification of non-ASCII |
| characters can vary across platforms even in similarly-named |
| locales. (But the <literal>C</literal> locale never considers any |
| non-ASCII characters to belong to any of these classes.) |
| In addition to these standard character |
| classes, <productname>PostgreSQL</productname> defines |
| the <literal>word</literal> character class, which is the same as |
| <literal>alnum</literal> plus the underscore (<literal>_</literal>) |
| character, and |
| the <literal>ascii</literal> character class, which contains exactly |
| the 7-bit ASCII set. |
| </para> |
| |
| <para> |
| There are two special cases of bracket expressions: the bracket |
| expressions <literal>[[:<:]]</literal> and |
| <literal>[[:>:]]</literal> are constraints, |
| matching empty strings at the beginning |
| and end of a word respectively. A word is defined as a sequence |
| of word characters that is neither preceded nor followed by word |
| characters. A word character is any character belonging to the |
| <literal>word</literal> character class, that is, any letter, digit, |
| or underscore. This is an extension, compatible with but not |
| specified by <acronym>POSIX</acronym> 1003.2, and should be used with |
| caution in software intended to be portable to other systems. |
| The constraint escapes described below are usually preferable; they |
| are no more standard, but are easier to type. |
| </para> |
| </sect3> |
| |
| <sect3 id="posix-escape-sequences"> |
| <title>Regular Expression Escapes</title> |
| |
| <para> |
| <firstterm>Escapes</firstterm> are special sequences beginning with <literal>\</literal> |
| followed by an alphanumeric character. Escapes come in several varieties: |
| character entry, class shorthands, constraint escapes, and back references. |
| A <literal>\</literal> followed by an alphanumeric character but not constituting |
| a valid escape is illegal in AREs. |
| In EREs, there are no escapes: outside a bracket expression, |
| a <literal>\</literal> followed by an alphanumeric character merely stands for |
| that character as an ordinary character, and inside a bracket expression, |
| <literal>\</literal> is an ordinary character. |
| (The latter is the one actual incompatibility between EREs and AREs.) |
| </para> |
| |
| <para> |
| <firstterm>Character-entry escapes</firstterm> exist to make it easier to specify |
| non-printing and other inconvenient characters in REs. They are |
| shown in <xref linkend="posix-character-entry-escapes-table"/>. |
| </para> |
| |
| <para> |
| <firstterm>Class-shorthand escapes</firstterm> provide shorthands for certain |
| commonly-used character classes. They are |
| shown in <xref linkend="posix-class-shorthand-escapes-table"/>. |
| </para> |
| |
| <para> |
| A <firstterm>constraint escape</firstterm> is a constraint, |
| matching the empty string if specific conditions are met, |
| written as an escape. They are |
| shown in <xref linkend="posix-constraint-escapes-table"/>. |
| </para> |
| |
| <para> |
| A <firstterm>back reference</firstterm> (<literal>\</literal><replaceable>n</replaceable>) matches the |
| same string matched by the previous parenthesized subexpression specified |
| by the number <replaceable>n</replaceable> |
| (see <xref linkend="posix-constraint-backref-table"/>). For example, |
| <literal>([bc])\1</literal> matches <literal>bb</literal> or <literal>cc</literal> |
| but not <literal>bc</literal> or <literal>cb</literal>. |
| The subexpression must entirely precede the back reference in the RE. |
| Subexpressions are numbered in the order of their leading parentheses. |
| Non-capturing parentheses do not define subexpressions. |
| The back reference considers only the string characters matched by the |
| referenced subexpression, not any constraints contained in it. For |
| example, <literal>(^\d)\1</literal> will match <literal>22</literal>. |
| </para> |
| |
| <table id="posix-character-entry-escapes-table"> |
| <title>Regular Expression Character-Entry Escapes</title> |
| |
| <tgroup cols="2"> |
| <thead> |
| <row> |
| <entry>Escape</entry> |
| <entry>Description</entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry> <literal>\a</literal> </entry> |
| <entry> alert (bell) character, as in C </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\b</literal> </entry> |
| <entry> backspace, as in C </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\B</literal> </entry> |
| <entry> synonym for backslash (<literal>\</literal>) to help reduce the need for backslash |
| doubling </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\c</literal><replaceable>X</replaceable> </entry> |
| <entry> (where <replaceable>X</replaceable> is any character) the character whose |
| low-order 5 bits are the same as those of |
| <replaceable>X</replaceable>, and whose other bits are all zero </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\e</literal> </entry> |
| <entry> the character whose collating-sequence name |
| is <literal>ESC</literal>, |
| or failing that, the character with octal value <literal>033</literal> </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\f</literal> </entry> |
| <entry> form feed, as in C </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\n</literal> </entry> |
| <entry> newline, as in C </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\r</literal> </entry> |
| <entry> carriage return, as in C </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\t</literal> </entry> |
| <entry> horizontal tab, as in C </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\u</literal><replaceable>wxyz</replaceable> </entry> |
| <entry> (where <replaceable>wxyz</replaceable> is exactly four hexadecimal digits) |
| the character whose hexadecimal value is |
| <literal>0x</literal><replaceable>wxyz</replaceable> |
| </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\U</literal><replaceable>stuvwxyz</replaceable> </entry> |
| <entry> (where <replaceable>stuvwxyz</replaceable> is exactly eight hexadecimal |
| digits) |
| the character whose hexadecimal value is |
| <literal>0x</literal><replaceable>stuvwxyz</replaceable> |
| </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\v</literal> </entry> |
| <entry> vertical tab, as in C </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\x</literal><replaceable>hhh</replaceable> </entry> |
| <entry> (where <replaceable>hhh</replaceable> is any sequence of hexadecimal |
| digits) |
| the character whose hexadecimal value is |
| <literal>0x</literal><replaceable>hhh</replaceable> |
| (a single character no matter how many hexadecimal digits are used) |
| </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\0</literal> </entry> |
| <entry> the character whose value is <literal>0</literal> (the null byte)</entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\</literal><replaceable>xy</replaceable> </entry> |
| <entry> (where <replaceable>xy</replaceable> is exactly two octal digits, |
| and is not a <firstterm>back reference</firstterm>) |
| the character whose octal value is |
| <literal>0</literal><replaceable>xy</replaceable> </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\</literal><replaceable>xyz</replaceable> </entry> |
| <entry> (where <replaceable>xyz</replaceable> is exactly three octal digits, |
| and is not a <firstterm>back reference</firstterm>) |
| the character whose octal value is |
| <literal>0</literal><replaceable>xyz</replaceable> </entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| Hexadecimal digits are <literal>0</literal>-<literal>9</literal>, |
| <literal>a</literal>-<literal>f</literal>, and <literal>A</literal>-<literal>F</literal>. |
| Octal digits are <literal>0</literal>-<literal>7</literal>. |
| </para> |
| |
| <para> |
| Numeric character-entry escapes specifying values outside the ASCII range |
| (0–127) have meanings dependent on the database encoding. When the |
| encoding is UTF-8, escape values are equivalent to Unicode code points, |
| for example <literal>\u1234</literal> means the character <literal>U+1234</literal>. |
| For other multibyte encodings, character-entry escapes usually just |
| specify the concatenation of the byte values for the character. If the |
| escape value does not correspond to any legal character in the database |
| encoding, no error will be raised, but it will never match any data. |
| </para> |
| |
| <para> |
| The character-entry escapes are always taken as ordinary characters. |
| For example, <literal>\135</literal> is <literal>]</literal> in ASCII, but |
| <literal>\135</literal> does not terminate a bracket expression. |
| </para> |
| |
| <table id="posix-class-shorthand-escapes-table"> |
| <title>Regular Expression Class-Shorthand Escapes</title> |
| |
| <tgroup cols="2"> |
| <thead> |
| <row> |
| <entry>Escape</entry> |
| <entry>Description</entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry> <literal>\d</literal> </entry> |
| <entry> matches any digit, like |
| <literal>[[:digit:]]</literal> </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\s</literal> </entry> |
| <entry> matches any whitespace character, like |
| <literal>[[:space:]]</literal> </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\w</literal> </entry> |
| <entry> matches any word character, like |
| <literal>[[:word:]]</literal> </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\D</literal> </entry> |
| <entry> matches any non-digit, like |
| <literal>[^[:digit:]]</literal> </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\S</literal> </entry> |
| <entry> matches any non-whitespace character, like |
| <literal>[^[:space:]]</literal> </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\W</literal> </entry> |
| <entry> matches any non-word character, like |
| <literal>[^[:word:]]</literal> </entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| The class-shorthand escapes also work within bracket expressions, |
| although the definitions shown above are not quite syntactically |
| valid in that context. |
| For example, <literal>[a-c\d]</literal> is equivalent to |
| <literal>[a-c[:digit:]]</literal>. |
| </para> |
| |
| <table id="posix-constraint-escapes-table"> |
| <title>Regular Expression Constraint Escapes</title> |
| |
| <tgroup cols="2"> |
| <thead> |
| <row> |
| <entry>Escape</entry> |
| <entry>Description</entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry> <literal>\A</literal> </entry> |
| <entry> matches only at the beginning of the string |
| (see <xref linkend="posix-matching-rules"/> for how this differs from |
| <literal>^</literal>) </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\m</literal> </entry> |
| <entry> matches only at the beginning of a word </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\M</literal> </entry> |
| <entry> matches only at the end of a word </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\y</literal> </entry> |
| <entry> matches only at the beginning or end of a word </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\Y</literal> </entry> |
| <entry> matches only at a point that is not the beginning or end of a |
| word </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\Z</literal> </entry> |
| <entry> matches only at the end of the string |
| (see <xref linkend="posix-matching-rules"/> for how this differs from |
| <literal>$</literal>) </entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| A word is defined as in the specification of |
| <literal>[[:<:]]</literal> and <literal>[[:>:]]</literal> above. |
| Constraint escapes are illegal within bracket expressions. |
| </para> |
| |
| <table id="posix-constraint-backref-table"> |
| <title>Regular Expression Back References</title> |
| |
| <tgroup cols="2"> |
| <thead> |
| <row> |
| <entry>Escape</entry> |
| <entry>Description</entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry> <literal>\</literal><replaceable>m</replaceable> </entry> |
| <entry> (where <replaceable>m</replaceable> is a nonzero digit) |
| a back reference to the <replaceable>m</replaceable>'th subexpression </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>\</literal><replaceable>mnn</replaceable> </entry> |
| <entry> (where <replaceable>m</replaceable> is a nonzero digit, and |
| <replaceable>nn</replaceable> is some more digits, and the decimal value |
| <replaceable>mnn</replaceable> is not greater than the number of closing capturing |
| parentheses seen so far) |
| a back reference to the <replaceable>mnn</replaceable>'th subexpression </entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <note> |
| <para> |
| There is an inherent ambiguity between octal character-entry |
| escapes and back references, which is resolved by the following heuristics, |
| as hinted at above. |
| A leading zero always indicates an octal escape. |
| A single non-zero digit, not followed by another digit, |
| is always taken as a back reference. |
| A multi-digit sequence not starting with a zero is taken as a back |
| reference if it comes after a suitable subexpression |
| (i.e., the number is in the legal range for a back reference), |
| and otherwise is taken as octal. |
| </para> |
| </note> |
| </sect3> |
| |
| <sect3 id="posix-metasyntax"> |
| <title>Regular Expression Metasyntax</title> |
| |
| <para> |
| In addition to the main syntax described above, there are some special |
| forms and miscellaneous syntactic facilities available. |
| </para> |
| |
| <para> |
| An RE can begin with one of two special <firstterm>director</firstterm> prefixes. |
| If an RE begins with <literal>***:</literal>, |
| the rest of the RE is taken as an ARE. (This normally has no effect in |
| <productname>PostgreSQL</productname>, since REs are assumed to be AREs; |
| but it does have an effect if ERE or BRE mode had been specified by |
| the <replaceable>flags</replaceable> parameter to a regex function.) |
| If an RE begins with <literal>***=</literal>, |
| the rest of the RE is taken to be a literal string, |
| with all characters considered ordinary characters. |
| </para> |
| |
| <para> |
| An ARE can begin with <firstterm>embedded options</firstterm>: |
| a sequence <literal>(?</literal><replaceable>xyz</replaceable><literal>)</literal> |
| (where <replaceable>xyz</replaceable> is one or more alphabetic characters) |
| specifies options affecting the rest of the RE. |
| These options override any previously determined options — |
| in particular, they can override the case-sensitivity behavior implied by |
| a regex operator, or the <replaceable>flags</replaceable> parameter to a regex |
| function. |
| The available option letters are |
| shown in <xref linkend="posix-embedded-options-table"/>. |
| Note that these same option letters are used in the <replaceable>flags</replaceable> |
| parameters of regex functions. |
| </para> |
| |
| <table id="posix-embedded-options-table"> |
| <title>ARE Embedded-Option Letters</title> |
| |
| <tgroup cols="2"> |
| <thead> |
| <row> |
| <entry>Option</entry> |
| <entry>Description</entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry> <literal>b</literal> </entry> |
| <entry> rest of RE is a BRE </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>c</literal> </entry> |
| <entry> case-sensitive matching (overrides operator type) </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>e</literal> </entry> |
| <entry> rest of RE is an ERE </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>i</literal> </entry> |
| <entry> case-insensitive matching (see |
| <xref linkend="posix-matching-rules"/>) (overrides operator type) </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>m</literal> </entry> |
| <entry> historical synonym for <literal>n</literal> </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>n</literal> </entry> |
| <entry> newline-sensitive matching (see |
| <xref linkend="posix-matching-rules"/>) </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>p</literal> </entry> |
| <entry> partial newline-sensitive matching (see |
| <xref linkend="posix-matching-rules"/>) </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>q</literal> </entry> |
| <entry> rest of RE is a literal (<quote>quoted</quote>) string, all ordinary |
| characters </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>s</literal> </entry> |
| <entry> non-newline-sensitive matching (default) </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>t</literal> </entry> |
| <entry> tight syntax (default; see below) </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>w</literal> </entry> |
| <entry> inverse partial newline-sensitive (<quote>weird</quote>) matching |
| (see <xref linkend="posix-matching-rules"/>) </entry> |
| </row> |
| |
| <row> |
| <entry> <literal>x</literal> </entry> |
| <entry> expanded syntax (see below) </entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| Embedded options take effect at the <literal>)</literal> terminating the sequence. |
| They can appear only at the start of an ARE (after the |
| <literal>***:</literal> director if any). |
| </para> |
| |
| <para> |
| In addition to the usual (<firstterm>tight</firstterm>) RE syntax, in which all |
| characters are significant, there is an <firstterm>expanded</firstterm> syntax, |
| available by specifying the embedded <literal>x</literal> option. |
| In the expanded syntax, |
| white-space characters in the RE are ignored, as are |
| all characters between a <literal>#</literal> |
| and the following newline (or the end of the RE). This |
| permits paragraphing and commenting a complex RE. |
| There are three exceptions to that basic rule: |
| |
| <itemizedlist> |
| <listitem> |
| <para> |
| a white-space character or <literal>#</literal> preceded by <literal>\</literal> is |
| retained |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| white space or <literal>#</literal> within a bracket expression is retained |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| white space and comments cannot appear within multi-character symbols, |
| such as <literal>(?:</literal> |
| </para> |
| </listitem> |
| </itemizedlist> |
| |
| For this purpose, white-space characters are blank, tab, newline, and |
| any character that belongs to the <replaceable>space</replaceable> character class. |
| </para> |
| |
| <para> |
| Finally, in an ARE, outside bracket expressions, the sequence |
| <literal>(?#</literal><replaceable>ttt</replaceable><literal>)</literal> |
| (where <replaceable>ttt</replaceable> is any text not containing a <literal>)</literal>) |
| is a comment, completely ignored. |
| Again, this is not allowed between the characters of |
| multi-character symbols, like <literal>(?:</literal>. |
| Such comments are more a historical artifact than a useful facility, |
| and their use is deprecated; use the expanded syntax instead. |
| </para> |
| |
| <para> |
| <emphasis>None</emphasis> of these metasyntax extensions is available if |
| an initial <literal>***=</literal> director |
| has specified that the user's input be treated as a literal string |
| rather than as an RE. |
| </para> |
| </sect3> |
| |
| <sect3 id="posix-matching-rules"> |
| <title>Regular Expression Matching Rules</title> |
| |
| <para> |
| In the event that an RE could match more than one substring of a given |
| string, the RE matches the one starting earliest in the string. |
| If the RE could match more than one substring starting at that point, |
| either the longest possible match or the shortest possible match will |
| be taken, depending on whether the RE is <firstterm>greedy</firstterm> or |
| <firstterm>non-greedy</firstterm>. |
| </para> |
| |
| <para> |
| Whether an RE is greedy or not is determined by the following rules: |
| <itemizedlist> |
| <listitem> |
| <para> |
| Most atoms, and all constraints, have no greediness attribute (because |
| they cannot match variable amounts of text anyway). |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| Adding parentheses around an RE does not change its greediness. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| A quantified atom with a fixed-repetition quantifier |
| (<literal>{</literal><replaceable>m</replaceable><literal>}</literal> |
| or |
| <literal>{</literal><replaceable>m</replaceable><literal>}?</literal>) |
| has the same greediness (possibly none) as the atom itself. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| A quantified atom with other normal quantifiers (including |
| <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}</literal> |
| with <replaceable>m</replaceable> equal to <replaceable>n</replaceable>) |
| is greedy (prefers longest match). |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| A quantified atom with a non-greedy quantifier (including |
| <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}?</literal> |
| with <replaceable>m</replaceable> equal to <replaceable>n</replaceable>) |
| is non-greedy (prefers shortest match). |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| A branch — that is, an RE that has no top-level |
| <literal>|</literal> operator — has the same greediness as the first |
| quantified atom in it that has a greediness attribute. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| An RE consisting of two or more branches connected by the |
| <literal>|</literal> operator is always greedy. |
| </para> |
| </listitem> |
| </itemizedlist> |
| </para> |
| |
| <para> |
| The above rules associate greediness attributes not only with individual |
| quantified atoms, but with branches and entire REs that contain quantified |
| atoms. What that means is that the matching is done in such a way that |
| the branch, or whole RE, matches the longest or shortest possible |
| substring <emphasis>as a whole</emphasis>. Once the length of the entire match |
| is determined, the part of it that matches any particular subexpression |
| is determined on the basis of the greediness attribute of that |
| subexpression, with subexpressions starting earlier in the RE taking |
| priority over ones starting later. |
| </para> |
| |
| <para> |
| An example of what this means: |
| <screen> |
| SELECT SUBSTRING('XY1234Z', 'Y*([0-9]{1,3})'); |
| <lineannotation>Result: </lineannotation><computeroutput>123</computeroutput> |
| SELECT SUBSTRING('XY1234Z', 'Y*?([0-9]{1,3})'); |
| <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput> |
| </screen> |
| In the first case, the RE as a whole is greedy because <literal>Y*</literal> |
| is greedy. It can match beginning at the <literal>Y</literal>, and it matches |
| the longest possible string starting there, i.e., <literal>Y123</literal>. |
| The output is the parenthesized part of that, or <literal>123</literal>. |
| In the second case, the RE as a whole is non-greedy because <literal>Y*?</literal> |
| is non-greedy. It can match beginning at the <literal>Y</literal>, and it matches |
| the shortest possible string starting there, i.e., <literal>Y1</literal>. |
| The subexpression <literal>[0-9]{1,3}</literal> is greedy but it cannot change |
| the decision as to the overall match length; so it is forced to match |
| just <literal>1</literal>. |
| </para> |
| |
| <para> |
| In short, when an RE contains both greedy and non-greedy subexpressions, |
| the total match length is either as long as possible or as short as |
| possible, according to the attribute assigned to the whole RE. The |
| attributes assigned to the subexpressions only affect how much of that |
| match they are allowed to <quote>eat</quote> relative to each other. |
| </para> |
| |
| <para> |
| The quantifiers <literal>{1,1}</literal> and <literal>{1,1}?</literal> |
| can be used to force greediness or non-greediness, respectively, |
| on a subexpression or a whole RE. |
| This is useful when you need the whole RE to have a greediness attribute |
| different from what's deduced from its elements. As an example, |
| suppose that we are trying to separate a string containing some digits |
| into the digits and the parts before and after them. We might try to |
| do that like this: |
| <screen> |
| SELECT regexp_match('abc01234xyz', '(.*)(\d+)(.*)'); |
| <lineannotation>Result: </lineannotation><computeroutput>{abc0123,4,xyz}</computeroutput> |
| </screen> |
| That didn't work: the first <literal>.*</literal> is greedy so |
| it <quote>eats</quote> as much as it can, leaving the <literal>\d+</literal> to |
| match at the last possible place, the last digit. We might try to fix |
| that by making it non-greedy: |
| <screen> |
| SELECT regexp_match('abc01234xyz', '(.*?)(\d+)(.*)'); |
| <lineannotation>Result: </lineannotation><computeroutput>{abc,0,""}</computeroutput> |
| </screen> |
| That didn't work either, because now the RE as a whole is non-greedy |
| and so it ends the overall match as soon as possible. We can get what |
| we want by forcing the RE as a whole to be greedy: |
| <screen> |
| SELECT regexp_match('abc01234xyz', '(?:(.*?)(\d+)(.*)){1,1}'); |
| <lineannotation>Result: </lineannotation><computeroutput>{abc,01234,xyz}</computeroutput> |
| </screen> |
| Controlling the RE's overall greediness separately from its components' |
| greediness allows great flexibility in handling variable-length patterns. |
| </para> |
| |
| <para> |
| When deciding what is a longer or shorter match, |
| match lengths are measured in characters, not collating elements. |
| An empty string is considered longer than no match at all. |
| For example: |
| <literal>bb*</literal> |
| matches the three middle characters of <literal>abbbc</literal>; |
| <literal>(week|wee)(night|knights)</literal> |
| matches all ten characters of <literal>weeknights</literal>; |
| when <literal>(.*).*</literal> |
| is matched against <literal>abc</literal> the parenthesized subexpression |
| matches all three characters; and when |
| <literal>(a*)*</literal> is matched against <literal>bc</literal> |
| both the whole RE and the parenthesized |
| subexpression match an empty string. |
| </para> |
| |
| <para> |
| If case-independent matching is specified, |
| the effect is much as if all case distinctions had vanished from the |
| alphabet. |
| When an alphabetic that exists in multiple cases appears as an |
| ordinary character outside a bracket expression, it is effectively |
| transformed into a bracket expression containing both cases, |
| e.g., <literal>x</literal> becomes <literal>[xX]</literal>. |
| When it appears inside a bracket expression, all case counterparts |
| of it are added to the bracket expression, e.g., |
| <literal>[x]</literal> becomes <literal>[xX]</literal> |
| and <literal>[^x]</literal> becomes <literal>[^xX]</literal>. |
| </para> |
| |
| <para> |
| If newline-sensitive matching is specified, <literal>.</literal> |
| and bracket expressions using <literal>^</literal> |
| will never match the newline character |
| (so that matches will not cross lines unless the RE |
| explicitly includes a newline) |
| and <literal>^</literal> and <literal>$</literal> |
| will match the empty string after and before a newline |
| respectively, in addition to matching at beginning and end of string |
| respectively. |
| But the ARE escapes <literal>\A</literal> and <literal>\Z</literal> |
| continue to match beginning or end of string <emphasis>only</emphasis>. |
| Also, the character class shorthands <literal>\D</literal> |
| and <literal>\W</literal> will match a newline regardless of this mode. |
| (Before <productname>PostgreSQL</productname> 14, they did not match |
| newlines when in newline-sensitive mode. |
| Write <literal>[^[:digit:]]</literal> |
| or <literal>[^[:word:]]</literal> to get the old behavior.) |
| </para> |
| |
| <para> |
| If partial newline-sensitive matching is specified, |
| this affects <literal>.</literal> and bracket expressions |
| as with newline-sensitive matching, but not <literal>^</literal> |
| and <literal>$</literal>. |
| </para> |
| |
| <para> |
| If inverse partial newline-sensitive matching is specified, |
| this affects <literal>^</literal> and <literal>$</literal> |
| as with newline-sensitive matching, but not <literal>.</literal> |
| and bracket expressions. |
| This isn't very useful but is provided for symmetry. |
| </para> |
| </sect3> |
| |
| <sect3 id="posix-limits-compatibility"> |
| <title>Limits and Compatibility</title> |
| |
| <para> |
| No particular limit is imposed on the length of REs in this |
| implementation. However, |
| programs intended to be highly portable should not employ REs longer |
| than 256 bytes, |
| as a POSIX-compliant implementation can refuse to accept such REs. |
| </para> |
| |
| <para> |
| The only feature of AREs that is actually incompatible with |
| POSIX EREs is that <literal>\</literal> does not lose its special |
| significance inside bracket expressions. |
| All other ARE features use syntax which is illegal or has |
| undefined or unspecified effects in POSIX EREs; |
| the <literal>***</literal> syntax of directors likewise is outside the POSIX |
| syntax for both BREs and EREs. |
| </para> |
| |
| <para> |
| Many of the ARE extensions are borrowed from Perl, but some have |
| been changed to clean them up, and a few Perl extensions are not present. |
| Incompatibilities of note include <literal>\b</literal>, <literal>\B</literal>, |
| the lack of special treatment for a trailing newline, |
| the addition of complemented bracket expressions to the things |
| affected by newline-sensitive matching, |
| the restrictions on parentheses and back references in lookahead/lookbehind |
| constraints, and the longest/shortest-match (rather than first-match) |
| matching semantics. |
| </para> |
| </sect3> |
| |
| <sect3 id="posix-basic-regexes"> |
| <title>Basic Regular Expressions</title> |
| |
| <para> |
| BREs differ from EREs in several respects. |
| In BREs, <literal>|</literal>, <literal>+</literal>, and <literal>?</literal> |
| are ordinary characters and there is no equivalent |
| for their functionality. |
| The delimiters for bounds are |
| <literal>\{</literal> and <literal>\}</literal>, |
| with <literal>{</literal> and <literal>}</literal> |
| by themselves ordinary characters. |
| The parentheses for nested subexpressions are |
| <literal>\(</literal> and <literal>\)</literal>, |
| with <literal>(</literal> and <literal>)</literal> by themselves ordinary characters. |
| <literal>^</literal> is an ordinary character except at the beginning of the |
| RE or the beginning of a parenthesized subexpression, |
| <literal>$</literal> is an ordinary character except at the end of the |
| RE or the end of a parenthesized subexpression, |
| and <literal>*</literal> is an ordinary character if it appears at the beginning |
| of the RE or the beginning of a parenthesized subexpression |
| (after a possible leading <literal>^</literal>). |
| Finally, single-digit back references are available, and |
| <literal>\<</literal> and <literal>\></literal> |
| are synonyms for |
| <literal>[[:<:]]</literal> and <literal>[[:>:]]</literal> |
| respectively; no other escapes are available in BREs. |
| </para> |
| </sect3> |
| |
| <!-- end re_syntax.n man page --> |
| |
| <sect3 id="posix-vs-xquery"> |
| <title>Differences from XQuery (<literal>LIKE_REGEX</literal>)</title> |
| |
| <indexterm zone="posix-vs-xquery"> |
| <primary><literal>LIKE_REGEX</literal></primary> |
| </indexterm> |
| |
| <indexterm zone="posix-vs-xquery"> |
| <primary>XQuery regular expressions</primary> |
| </indexterm> |
| |
| <para> |
| Since SQL:2008, the SQL standard includes |
| a <literal>LIKE_REGEX</literal> operator that performs pattern |
| matching according to the XQuery regular expression |
| standard. <productname>PostgreSQL</productname> does not yet |
| implement this operator, but you can get very similar behavior using |
| the <function>regexp_match()</function> function, since XQuery |
| regular expressions are quite close to the ARE syntax described above. |
| </para> |
| |
| <para> |
| Notable differences between the existing POSIX-based |
| regular-expression feature and XQuery regular expressions include: |
| |
| <itemizedlist> |
| <listitem> |
| <para> |
| XQuery character class subtraction is not supported. An example of |
| this feature is using the following to match only English |
| consonants: <literal>[a-z-[aeiou]]</literal>. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| XQuery character class shorthands <literal>\c</literal>, |
| <literal>\C</literal>, <literal>\i</literal>, |
| and <literal>\I</literal> are not supported. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| XQuery character class elements |
| using <literal>\p{UnicodeProperty}</literal> or the |
| inverse <literal>\P{UnicodeProperty}</literal> are not supported. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| POSIX interprets character classes such as <literal>\w</literal> |
| (see <xref linkend="posix-class-shorthand-escapes-table"/>) |
| according to the prevailing locale (which you can control by |
| attaching a <literal>COLLATE</literal> clause to the operator or |
| function). XQuery specifies these classes by reference to Unicode |
| character properties, so equivalent behavior is obtained only with |
| a locale that follows the Unicode rules. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| The SQL standard (not XQuery itself) attempts to cater for more |
| variants of <quote>newline</quote> than POSIX does. The |
| newline-sensitive matching options described above consider only |
| ASCII NL (<literal>\n</literal>) to be a newline, but SQL would have |
| us treat CR (<literal>\r</literal>), CRLF (<literal>\r\n</literal>) |
| (a Windows-style newline), and some Unicode-only characters like |
| LINE SEPARATOR (U+2028) as newlines as well. |
| Notably, <literal>.</literal> and <literal>\s</literal> should |
| count <literal>\r\n</literal> as one character not two according to |
| SQL. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| Of the character-entry escapes described in |
| <xref linkend="posix-character-entry-escapes-table"/>, |
| XQuery supports only <literal>\n</literal>, <literal>\r</literal>, |
| and <literal>\t</literal>. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| XQuery does not support |
| the <literal>[:<replaceable>name</replaceable>:]</literal> syntax |
| for character classes within bracket expressions. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| XQuery does not have lookahead or lookbehind constraints, |
| nor any of the constraint escapes described in |
| <xref linkend="posix-constraint-escapes-table"/>. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| The metasyntax forms described in <xref linkend="posix-metasyntax"/> |
| do not exist in XQuery. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| The regular expression flag letters defined by XQuery are |
| related to but not the same as the option letters for POSIX |
| (<xref linkend="posix-embedded-options-table"/>). While the |
| <literal>i</literal> and <literal>q</literal> options behave the |
| same, others do not: |
| <itemizedlist> |
| <listitem> |
| <para> |
| XQuery's <literal>s</literal> (allow dot to match newline) |
| and <literal>m</literal> (allow <literal>^</literal> |
| and <literal>$</literal> to match at newlines) flags provide |
| access to the same behaviors as |
| POSIX's <literal>n</literal>, <literal>p</literal> |
| and <literal>w</literal> flags, but they |
| do <emphasis>not</emphasis> match the behavior of |
| POSIX's <literal>s</literal> and <literal>m</literal> flags. |
| Note in particular that dot-matches-newline is the default |
| behavior in POSIX but not XQuery. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| XQuery's <literal>x</literal> (ignore whitespace in pattern) flag |
| is noticeably different from POSIX's expanded-mode flag. |
| POSIX's <literal>x</literal> flag also |
| allows <literal>#</literal> to begin a comment in the pattern, |
| and POSIX will not ignore a whitespace character after a |
| backslash. |
| </para> |
| </listitem> |
| </itemizedlist> |
| </para> |
| </listitem> |
| </itemizedlist> |
| </para> |
| |
| </sect3> |
| </sect2> |
| </sect1> |
| |
| |
| <sect1 id="functions-formatting"> |
| <title>Data Type Formatting Functions</title> |
| |
| <indexterm> |
| <primary>formatting</primary> |
| </indexterm> |
| |
| <para> |
| The <productname>PostgreSQL</productname> formatting functions |
| provide a powerful set of tools for converting various data types |
| (date/time, integer, floating point, numeric) to formatted strings |
| and for converting from formatted strings to specific data types. |
| <xref linkend="functions-formatting-table"/> lists them. |
| These functions all follow a common calling convention: the first |
| argument is the value to be formatted and the second argument is a |
| template that defines the output or input format. |
| </para> |
| |
| <table id="functions-formatting-table"> |
| <title>Formatting Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>to_char</primary> |
| </indexterm> |
| <function>to_char</function> ( <type>timestamp</type>, <type>text</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>to_char</function> ( <type>timestamp with time zone</type>, <type>text</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Converts time stamp to string according to the given format. |
| </para> |
| <para> |
| <literal>to_char(timestamp '2002-04-20 17:31:12.66', 'HH12:MI:SS')</literal> |
| <returnvalue>05:31:12</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>to_char</function> ( <type>interval</type>, <type>text</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Converts interval to string according to the given format. |
| </para> |
| <para> |
| <literal>to_char(interval '15h 2m 12s', 'HH24:MI:SS')</literal> |
| <returnvalue>15:02:12</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>to_char</function> ( <replaceable>numeric_type</replaceable>, <type>text</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Converts number to string according to the given format; available |
| for <type>integer</type>, <type>bigint</type>, <type>numeric</type>, |
| <type>real</type>, <type>double precision</type>. |
| </para> |
| <para> |
| <literal>to_char(125, '999')</literal> |
| <returnvalue>125</returnvalue> |
| </para> |
| <para> |
| <literal>to_char(125.8::real, '999D9')</literal> |
| <returnvalue>125.8</returnvalue> |
| </para> |
| <para> |
| <literal>to_char(-125.8, '999D99S')</literal> |
| <returnvalue>125.80-</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>to_date</primary> |
| </indexterm> |
| <function>to_date</function> ( <type>text</type>, <type>text</type> ) |
| <returnvalue>date</returnvalue> |
| </para> |
| <para> |
| Converts string to date according to the given format. |
| </para> |
| <para> |
| <literal>to_date('05 Dec 2000', 'DD Mon YYYY')</literal> |
| <returnvalue>2000-12-05</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>to_number</primary> |
| </indexterm> |
| <function>to_number</function> ( <type>text</type>, <type>text</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para> |
| Converts string to numeric according to the given format. |
| </para> |
| <para> |
| <literal>to_number('12,454.8-', '99G999D9S')</literal> |
| <returnvalue>-12454.8</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>to_timestamp</primary> |
| </indexterm> |
| <function>to_timestamp</function> ( <type>text</type>, <type>text</type> ) |
| <returnvalue>timestamp with time zone</returnvalue> |
| </para> |
| <para> |
| Converts string to time stamp according to the given format. |
| (See also <function>to_timestamp(double precision)</function> in |
| <xref linkend="functions-datetime-table"/>.) |
| </para> |
| <para> |
| <literal>to_timestamp('05 Dec 2000', 'DD Mon YYYY')</literal> |
| <returnvalue>2000-12-05 00:00:00-05</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <tip> |
| <para> |
| <function>to_timestamp</function> and <function>to_date</function> |
| exist to handle input formats that cannot be converted by |
| simple casting. For most standard date/time formats, simply casting the |
| source string to the required data type works, and is much easier. |
| Similarly, <function>to_number</function> is unnecessary for standard numeric |
| representations. |
| </para> |
| </tip> |
| |
| <para> |
| In a <function>to_char</function> output template string, there are certain |
| patterns that are recognized and replaced with appropriately-formatted |
| data based on the given value. Any text that is not a template pattern is |
| simply copied verbatim. Similarly, in an input template string (for the |
| other functions), template patterns identify the values to be supplied by |
| the input data string. If there are characters in the template string |
| that are not template patterns, the corresponding characters in the input |
| data string are simply skipped over (whether or not they are equal to the |
| template string characters). |
| </para> |
| |
| <para> |
| <xref linkend="functions-formatting-datetime-table"/> shows the |
| template patterns available for formatting date and time values. |
| </para> |
| |
| <table id="functions-formatting-datetime-table"> |
| <title>Template Patterns for Date/Time Formatting</title> |
| <tgroup cols="2"> |
| <thead> |
| <row> |
| <entry>Pattern</entry> |
| <entry>Description</entry> |
| </row> |
| </thead> |
| <tbody> |
| <row> |
| <entry><literal>HH</literal></entry> |
| <entry>hour of day (01–12)</entry> |
| </row> |
| <row> |
| <entry><literal>HH12</literal></entry> |
| <entry>hour of day (01–12)</entry> |
| </row> |
| <row> |
| <entry><literal>HH24</literal></entry> |
| <entry>hour of day (00–23)</entry> |
| </row> |
| <row> |
| <entry><literal>MI</literal></entry> |
| <entry>minute (00–59)</entry> |
| </row> |
| <row> |
| <entry><literal>SS</literal></entry> |
| <entry>second (00–59)</entry> |
| </row> |
| <row> |
| <entry><literal>MS</literal></entry> |
| <entry>millisecond (000–999)</entry> |
| </row> |
| <row> |
| <entry><literal>US</literal></entry> |
| <entry>microsecond (000000–999999)</entry> |
| </row> |
| <row> |
| <entry><literal>FF1</literal></entry> |
| <entry>tenth of second (0–9)</entry> |
| </row> |
| <row> |
| <entry><literal>FF2</literal></entry> |
| <entry>hundredth of second (00–99)</entry> |
| </row> |
| <row> |
| <entry><literal>FF3</literal></entry> |
| <entry>millisecond (000–999)</entry> |
| </row> |
| <row> |
| <entry><literal>FF4</literal></entry> |
| <entry>tenth of a millisecond (0000–9999)</entry> |
| </row> |
| <row> |
| <entry><literal>FF5</literal></entry> |
| <entry>hundredth of a millisecond (00000–99999)</entry> |
| </row> |
| <row> |
| <entry><literal>FF6</literal></entry> |
| <entry>microsecond (000000–999999)</entry> |
| </row> |
| <row> |
| <entry><literal>SSSS</literal>, <literal>SSSSS</literal></entry> |
| <entry>seconds past midnight (0–86399)</entry> |
| </row> |
| <row> |
| <entry><literal>AM</literal>, <literal>am</literal>, |
| <literal>PM</literal> or <literal>pm</literal></entry> |
| <entry>meridiem indicator (without periods)</entry> |
| </row> |
| <row> |
| <entry><literal>A.M.</literal>, <literal>a.m.</literal>, |
| <literal>P.M.</literal> or <literal>p.m.</literal></entry> |
| <entry>meridiem indicator (with periods)</entry> |
| </row> |
| <row> |
| <entry><literal>Y,YYY</literal></entry> |
| <entry>year (4 or more digits) with comma</entry> |
| </row> |
| <row> |
| <entry><literal>YYYY</literal></entry> |
| <entry>year (4 or more digits)</entry> |
| </row> |
| <row> |
| <entry><literal>YYY</literal></entry> |
| <entry>last 3 digits of year</entry> |
| </row> |
| <row> |
| <entry><literal>YY</literal></entry> |
| <entry>last 2 digits of year</entry> |
| </row> |
| <row> |
| <entry><literal>Y</literal></entry> |
| <entry>last digit of year</entry> |
| </row> |
| <row> |
| <entry><literal>IYYY</literal></entry> |
| <entry>ISO 8601 week-numbering year (4 or more digits)</entry> |
| </row> |
| <row> |
| <entry><literal>IYY</literal></entry> |
| <entry>last 3 digits of ISO 8601 week-numbering year</entry> |
| </row> |
| <row> |
| <entry><literal>IY</literal></entry> |
| <entry>last 2 digits of ISO 8601 week-numbering year</entry> |
| </row> |
| <row> |
| <entry><literal>I</literal></entry> |
| <entry>last digit of ISO 8601 week-numbering year</entry> |
| </row> |
| <row> |
| <entry><literal>BC</literal>, <literal>bc</literal>, |
| <literal>AD</literal> or <literal>ad</literal></entry> |
| <entry>era indicator (without periods)</entry> |
| </row> |
| <row> |
| <entry><literal>B.C.</literal>, <literal>b.c.</literal>, |
| <literal>A.D.</literal> or <literal>a.d.</literal></entry> |
| <entry>era indicator (with periods)</entry> |
| </row> |
| <row> |
| <entry><literal>MONTH</literal></entry> |
| <entry>full upper case month name (blank-padded to 9 chars)</entry> |
| </row> |
| <row> |
| <entry><literal>Month</literal></entry> |
| <entry>full capitalized month name (blank-padded to 9 chars)</entry> |
| </row> |
| <row> |
| <entry><literal>month</literal></entry> |
| <entry>full lower case month name (blank-padded to 9 chars)</entry> |
| </row> |
| <row> |
| <entry><literal>MON</literal></entry> |
| <entry>abbreviated upper case month name (3 chars in English, localized lengths vary)</entry> |
| </row> |
| <row> |
| <entry><literal>Mon</literal></entry> |
| <entry>abbreviated capitalized month name (3 chars in English, localized lengths vary)</entry> |
| </row> |
| <row> |
| <entry><literal>mon</literal></entry> |
| <entry>abbreviated lower case month name (3 chars in English, localized lengths vary)</entry> |
| </row> |
| <row> |
| <entry><literal>MM</literal></entry> |
| <entry>month number (01–12)</entry> |
| </row> |
| <row> |
| <entry><literal>DAY</literal></entry> |
| <entry>full upper case day name (blank-padded to 9 chars)</entry> |
| </row> |
| <row> |
| <entry><literal>Day</literal></entry> |
| <entry>full capitalized day name (blank-padded to 9 chars)</entry> |
| </row> |
| <row> |
| <entry><literal>day</literal></entry> |
| <entry>full lower case day name (blank-padded to 9 chars)</entry> |
| </row> |
| <row> |
| <entry><literal>DY</literal></entry> |
| <entry>abbreviated upper case day name (3 chars in English, localized lengths vary)</entry> |
| </row> |
| <row> |
| <entry><literal>Dy</literal></entry> |
| <entry>abbreviated capitalized day name (3 chars in English, localized lengths vary)</entry> |
| </row> |
| <row> |
| <entry><literal>dy</literal></entry> |
| <entry>abbreviated lower case day name (3 chars in English, localized lengths vary)</entry> |
| </row> |
| <row> |
| <entry><literal>DDD</literal></entry> |
| <entry>day of year (001–366)</entry> |
| </row> |
| <row> |
| <entry><literal>IDDD</literal></entry> |
| <entry>day of ISO 8601 week-numbering year (001–371; day 1 of the year is Monday of the first ISO week)</entry> |
| </row> |
| <row> |
| <entry><literal>DD</literal></entry> |
| <entry>day of month (01–31)</entry> |
| </row> |
| <row> |
| <entry><literal>D</literal></entry> |
| <entry>day of the week, Sunday (<literal>1</literal>) to Saturday (<literal>7</literal>)</entry> |
| </row> |
| <row> |
| <entry><literal>ID</literal></entry> |
| <entry>ISO 8601 day of the week, Monday (<literal>1</literal>) to Sunday (<literal>7</literal>)</entry> |
| </row> |
| <row> |
| <entry><literal>W</literal></entry> |
| <entry>week of month (1–5) (the first week starts on the first day of the month)</entry> |
| </row> |
| <row> |
| <entry><literal>WW</literal></entry> |
| <entry>week number of year (1–53) (the first week starts on the first day of the year)</entry> |
| </row> |
| <row> |
| <entry><literal>IW</literal></entry> |
| <entry>week number of ISO 8601 week-numbering year (01–53; the first Thursday of the year is in week 1)</entry> |
| </row> |
| <row> |
| <entry><literal>CC</literal></entry> |
| <entry>century (2 digits) (the twenty-first century starts on 2001-01-01)</entry> |
| </row> |
| <row> |
| <entry><literal>J</literal></entry> |
| <entry>Julian Date (integer days since November 24, 4714 BC at local |
| midnight; see <xref linkend="datetime-julian-dates"/>)</entry> |
| </row> |
| <row> |
| <entry><literal>Q</literal></entry> |
| <entry>quarter</entry> |
| </row> |
| <row> |
| <entry><literal>RM</literal></entry> |
| <entry>month in upper case Roman numerals (I–XII; I=January)</entry> |
| </row> |
| <row> |
| <entry><literal>rm</literal></entry> |
| <entry>month in lower case Roman numerals (i–xii; i=January)</entry> |
| </row> |
| <row> |
| <entry><literal>TZ</literal></entry> |
| <entry>upper case time-zone abbreviation |
| (only supported in <function>to_char</function>)</entry> |
| </row> |
| <row> |
| <entry><literal>tz</literal></entry> |
| <entry>lower case time-zone abbreviation |
| (only supported in <function>to_char</function>)</entry> |
| </row> |
| <row> |
| <entry><literal>TZH</literal></entry> |
| <entry>time-zone hours</entry> |
| </row> |
| <row> |
| <entry><literal>TZM</literal></entry> |
| <entry>time-zone minutes</entry> |
| </row> |
| <row> |
| <entry><literal>OF</literal></entry> |
| <entry>time-zone offset from UTC |
| (only supported in <function>to_char</function>)</entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| Modifiers can be applied to any template pattern to alter its |
| behavior. For example, <literal>FMMonth</literal> |
| is the <literal>Month</literal> pattern with the |
| <literal>FM</literal> modifier. |
| <xref linkend="functions-formatting-datetimemod-table"/> shows the |
| modifier patterns for date/time formatting. |
| </para> |
| |
| <table id="functions-formatting-datetimemod-table"> |
| <title>Template Pattern Modifiers for Date/Time Formatting</title> |
| <tgroup cols="3"> |
| <thead> |
| <row> |
| <entry>Modifier</entry> |
| <entry>Description</entry> |
| <entry>Example</entry> |
| </row> |
| </thead> |
| <tbody> |
| <row> |
| <entry><literal>FM</literal> prefix</entry> |
| <entry>fill mode (suppress leading zeroes and padding blanks)</entry> |
| <entry><literal>FMMonth</literal></entry> |
| </row> |
| <row> |
| <entry><literal>TH</literal> suffix</entry> |
| <entry>upper case ordinal number suffix</entry> |
| <entry><literal>DDTH</literal>, e.g., <literal>12TH</literal></entry> |
| </row> |
| <row> |
| <entry><literal>th</literal> suffix</entry> |
| <entry>lower case ordinal number suffix</entry> |
| <entry><literal>DDth</literal>, e.g., <literal>12th</literal></entry> |
| </row> |
| <row> |
| <entry><literal>FX</literal> prefix</entry> |
| <entry>fixed format global option (see usage notes)</entry> |
| <entry><literal>FX Month DD Day</literal></entry> |
| </row> |
| <row> |
| <entry><literal>TM</literal> prefix</entry> |
| <entry>translation mode (use localized day and month names based on |
| <xref linkend="guc-lc-time"/>)</entry> |
| <entry><literal>TMMonth</literal></entry> |
| </row> |
| <row> |
| <entry><literal>SP</literal> suffix</entry> |
| <entry>spell mode (not implemented)</entry> |
| <entry><literal>DDSP</literal></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| Usage notes for date/time formatting: |
| |
| <itemizedlist> |
| <listitem> |
| <para> |
| <literal>FM</literal> suppresses leading zeroes and trailing blanks |
| that would otherwise be added to make the output of a pattern be |
| fixed-width. In <productname>PostgreSQL</productname>, |
| <literal>FM</literal> modifies only the next specification, while in |
| Oracle <literal>FM</literal> affects all subsequent |
| specifications, and repeated <literal>FM</literal> modifiers |
| toggle fill mode on and off. |
| </para> |
| </listitem> |
| |
| <listitem> |
| <para> |
| <literal>TM</literal> suppresses trailing blanks whether or |
| not <literal>FM</literal> is specified. |
| </para> |
| </listitem> |
| |
| <listitem> |
| <para> |
| <function>to_timestamp</function> and <function>to_date</function> |
| ignore letter case in the input; so for |
| example <literal>MON</literal>, <literal>Mon</literal>, |
| and <literal>mon</literal> all accept the same strings. When using |
| the <literal>TM</literal> modifier, case-folding is done according to |
| the rules of the function's input collation (see |
| <xref linkend="collation"/>). |
| </para> |
| </listitem> |
| |
| <listitem> |
| <para> |
| <function>to_timestamp</function> and <function>to_date</function> |
| skip multiple blank spaces at the beginning of the input string and |
| around date and time values unless the <literal>FX</literal> option is used. For example, |
| <literal>to_timestamp(' 2000 JUN', 'YYYY MON')</literal> and |
| <literal>to_timestamp('2000 - JUN', 'YYYY-MON')</literal> work, but |
| <literal>to_timestamp('2000 JUN', 'FXYYYY MON')</literal> returns an error |
| because <function>to_timestamp</function> expects only a single space. |
| <literal>FX</literal> must be specified as the first item in |
| the template. |
| </para> |
| </listitem> |
| |
| <listitem> |
| <para> |
| A separator (a space or non-letter/non-digit character) in the template string of |
| <function>to_timestamp</function> and <function>to_date</function> |
| matches any single separator in the input string or is skipped, |
| unless the <literal>FX</literal> option is used. |
| For example, <literal>to_timestamp('2000JUN', 'YYYY///MON')</literal> and |
| <literal>to_timestamp('2000/JUN', 'YYYY MON')</literal> work, but |
| <literal>to_timestamp('2000//JUN', 'YYYY/MON')</literal> |
| returns an error because the number of separators in the input string |
| exceeds the number of separators in the template. |
| </para> |
| <para> |
| If <literal>FX</literal> is specified, a separator in the template string |
| matches exactly one character in the input string. But note that the |
| input string character is not required to be the same as the separator from the template string. |
| For example, <literal>to_timestamp('2000/JUN', 'FXYYYY MON')</literal> |
| works, but <literal>to_timestamp('2000/JUN', 'FXYYYY MON')</literal> |
| returns an error because the second space in the template string consumes |
| the letter <literal>J</literal> from the input string. |
| </para> |
| </listitem> |
| |
| <listitem> |
| <para> |
| A <literal>TZH</literal> template pattern can match a signed number. |
| Without the <literal>FX</literal> option, minus signs may be ambiguous, |
| and could be interpreted as a separator. |
| This ambiguity is resolved as follows: If the number of separators before |
| <literal>TZH</literal> in the template string is less than the number of |
| separators before the minus sign in the input string, the minus sign |
| is interpreted as part of <literal>TZH</literal>. |
| Otherwise, the minus sign is considered to be a separator between values. |
| For example, <literal>to_timestamp('2000 -10', 'YYYY TZH')</literal> matches |
| <literal>-10</literal> to <literal>TZH</literal>, but |
| <literal>to_timestamp('2000 -10', 'YYYY TZH')</literal> |
| matches <literal>10</literal> to <literal>TZH</literal>. |
| </para> |
| </listitem> |
| |
| <listitem> |
| <para> |
| Ordinary text is allowed in <function>to_char</function> |
| templates and will be output literally. You can put a substring |
| in double quotes to force it to be interpreted as literal text |
| even if it contains template patterns. For example, in |
| <literal>'"Hello Year "YYYY'</literal>, the <literal>YYYY</literal> |
| will be replaced by the year data, but the single <literal>Y</literal> in <literal>Year</literal> |
| will not be. |
| In <function>to_date</function>, <function>to_number</function>, |
| and <function>to_timestamp</function>, literal text and double-quoted |
| strings result in skipping the number of characters contained in the |
| string; for example <literal>"XX"</literal> skips two input characters |
| (whether or not they are <literal>XX</literal>). |
| </para> |
| <tip> |
| <para> |
| Prior to <productname>PostgreSQL</productname> 12, it was possible to |
| skip arbitrary text in the input string using non-letter or non-digit |
| characters. For example, |
| <literal>to_timestamp('2000y6m1d', 'yyyy-MM-DD')</literal> used to |
| work. Now you can only use letter characters for this purpose. For example, |
| <literal>to_timestamp('2000y6m1d', 'yyyytMMtDDt')</literal> and |
| <literal>to_timestamp('2000y6m1d', 'yyyy"y"MM"m"DD"d"')</literal> |
| skip <literal>y</literal>, <literal>m</literal>, and |
| <literal>d</literal>. |
| </para> |
| </tip> |
| </listitem> |
| |
| <listitem> |
| <para> |
| If you want to have a double quote in the output you must |
| precede it with a backslash, for example <literal>'\"YYYY |
| Month\"'</literal>. <!-- "" font-lock sanity :-) --> |
| Backslashes are not otherwise special outside of double-quoted |
| strings. Within a double-quoted string, a backslash causes the |
| next character to be taken literally, whatever it is (but this |
| has no special effect unless the next character is a double quote |
| or another backslash). |
| </para> |
| </listitem> |
| |
| <listitem> |
| <para> |
| In <function>to_timestamp</function> and <function>to_date</function>, |
| if the year format specification is less than four digits, e.g., |
| <literal>YYY</literal>, and the supplied year is less than four digits, |
| the year will be adjusted to be nearest to the year 2020, e.g., |
| <literal>95</literal> becomes 1995. |
| </para> |
| </listitem> |
| |
| <listitem> |
| <para> |
| In <function>to_timestamp</function> and <function>to_date</function>, |
| negative years are treated as signifying BC. If you write both a |
| negative year and an explicit <literal>BC</literal> field, you get AD |
| again. An input of year zero is treated as 1 BC. |
| </para> |
| </listitem> |
| |
| <listitem> |
| <para> |
| In <function>to_timestamp</function> and <function>to_date</function>, |
| the <literal>YYYY</literal> conversion has a restriction when |
| processing years with more than 4 digits. You must |
| use some non-digit character or template after <literal>YYYY</literal>, |
| otherwise the year is always interpreted as 4 digits. For example |
| (with the year 20000): |
| <literal>to_date('200001131', 'YYYYMMDD')</literal> will be |
| interpreted as a 4-digit year; instead use a non-digit |
| separator after the year, like |
| <literal>to_date('20000-1131', 'YYYY-MMDD')</literal> or |
| <literal>to_date('20000Nov31', 'YYYYMonDD')</literal>. |
| </para> |
| </listitem> |
| |
| <listitem> |
| <para> |
| In <function>to_timestamp</function> and <function>to_date</function>, |
| the <literal>CC</literal> (century) field is accepted but ignored |
| if there is a <literal>YYY</literal>, <literal>YYYY</literal> or |
| <literal>Y,YYY</literal> field. If <literal>CC</literal> is used with |
| <literal>YY</literal> or <literal>Y</literal> then the result is |
| computed as that year in the specified century. If the century is |
| specified but the year is not, the first year of the century |
| is assumed. |
| </para> |
| </listitem> |
| |
| <listitem> |
| <para> |
| In <function>to_timestamp</function> and <function>to_date</function>, |
| weekday names or numbers (<literal>DAY</literal>, <literal>D</literal>, |
| and related field types) are accepted but are ignored for purposes of |
| computing the result. The same is true for quarter |
| (<literal>Q</literal>) fields. |
| </para> |
| </listitem> |
| |
| <listitem> |
| <para> |
| In <function>to_timestamp</function> and <function>to_date</function>, |
| an ISO 8601 week-numbering date (as distinct from a Gregorian date) |
| can be specified in one of two ways: |
| <itemizedlist> |
| <listitem> |
| <para> |
| Year, week number, and weekday: for |
| example <literal>to_date('2006-42-4', 'IYYY-IW-ID')</literal> |
| returns the date <literal>2006-10-19</literal>. |
| If you omit the weekday it is assumed to be 1 (Monday). |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| Year and day of year: for example <literal>to_date('2006-291', |
| 'IYYY-IDDD')</literal> also returns <literal>2006-10-19</literal>. |
| </para> |
| </listitem> |
| </itemizedlist> |
| </para> |
| <para> |
| Attempting to enter a date using a mixture of ISO 8601 week-numbering |
| fields and Gregorian date fields is nonsensical, and will cause an |
| error. In the context of an ISO 8601 week-numbering year, the |
| concept of a <quote>month</quote> or <quote>day of month</quote> has no |
| meaning. In the context of a Gregorian year, the ISO week has no |
| meaning. |
| </para> |
| <caution> |
| <para> |
| While <function>to_date</function> will reject a mixture of |
| Gregorian and ISO week-numbering date |
| fields, <function>to_char</function> will not, since output format |
| specifications like <literal>YYYY-MM-DD (IYYY-IDDD)</literal> can be |
| useful. But avoid writing something like <literal>IYYY-MM-DD</literal>; |
| that would yield surprising results near the start of the year. |
| (See <xref linkend="functions-datetime-extract"/> for more |
| information.) |
| </para> |
| </caution> |
| </listitem> |
| |
| <listitem> |
| <para> |
| In <function>to_timestamp</function>, millisecond |
| (<literal>MS</literal>) or microsecond (<literal>US</literal>) |
| fields are used as the |
| seconds digits after the decimal point. For example |
| <literal>to_timestamp('12.3', 'SS.MS')</literal> is not 3 milliseconds, |
| but 300, because the conversion treats it as 12 + 0.3 seconds. |
| So, for the format <literal>SS.MS</literal>, the input values |
| <literal>12.3</literal>, <literal>12.30</literal>, |
| and <literal>12.300</literal> specify the |
| same number of milliseconds. To get three milliseconds, one must write |
| <literal>12.003</literal>, which the conversion treats as |
| 12 + 0.003 = 12.003 seconds. |
| </para> |
| |
| <para> |
| Here is a more |
| complex example: |
| <literal>to_timestamp('15:12:02.020.001230', 'HH24:MI:SS.MS.US')</literal> |
| is 15 hours, 12 minutes, and 2 seconds + 20 milliseconds + |
| 1230 microseconds = 2.021230 seconds. |
| </para> |
| </listitem> |
| |
| <listitem> |
| <para> |
| <function>to_char(..., 'ID')</function>'s day of the week numbering |
| matches the <function>extract(isodow from ...)</function> function, but |
| <function>to_char(..., 'D')</function>'s does not match |
| <function>extract(dow from ...)</function>'s day numbering. |
| </para> |
| </listitem> |
| |
| <listitem> |
| <para> |
| <function>to_char(interval)</function> formats <literal>HH</literal> and |
| <literal>HH12</literal> as shown on a 12-hour clock, for example zero hours |
| and 36 hours both output as <literal>12</literal>, while <literal>HH24</literal> |
| outputs the full hour value, which can exceed 23 in |
| an <type>interval</type> value. |
| </para> |
| </listitem> |
| |
| </itemizedlist> |
| </para> |
| |
| <para> |
| <xref linkend="functions-formatting-numeric-table"/> shows the |
| template patterns available for formatting numeric values. |
| </para> |
| |
| <table id="functions-formatting-numeric-table"> |
| <title>Template Patterns for Numeric Formatting</title> |
| <tgroup cols="2"> |
| <thead> |
| <row> |
| <entry>Pattern</entry> |
| <entry>Description</entry> |
| </row> |
| </thead> |
| <tbody> |
| <row> |
| <entry><literal>9</literal></entry> |
| <entry>digit position (can be dropped if insignificant)</entry> |
| </row> |
| <row> |
| <entry><literal>0</literal></entry> |
| <entry>digit position (will not be dropped, even if insignificant)</entry> |
| </row> |
| <row> |
| <entry><literal>.</literal> (period)</entry> |
| <entry>decimal point</entry> |
| </row> |
| <row> |
| <entry><literal>,</literal> (comma)</entry> |
| <entry>group (thousands) separator</entry> |
| </row> |
| <row> |
| <entry><literal>PR</literal></entry> |
| <entry>negative value in angle brackets</entry> |
| </row> |
| <row> |
| <entry><literal>S</literal></entry> |
| <entry>sign anchored to number (uses locale)</entry> |
| </row> |
| <row> |
| <entry><literal>L</literal></entry> |
| <entry>currency symbol (uses locale)</entry> |
| </row> |
| <row> |
| <entry><literal>D</literal></entry> |
| <entry>decimal point (uses locale)</entry> |
| </row> |
| <row> |
| <entry><literal>G</literal></entry> |
| <entry>group separator (uses locale)</entry> |
| </row> |
| <row> |
| <entry><literal>MI</literal></entry> |
| <entry>minus sign in specified position (if number < 0)</entry> |
| </row> |
| <row> |
| <entry><literal>PL</literal></entry> |
| <entry>plus sign in specified position (if number > 0)</entry> |
| </row> |
| <row> |
| <entry><literal>SG</literal></entry> |
| <entry>plus/minus sign in specified position</entry> |
| </row> |
| <row> |
| <entry><literal>RN</literal></entry> |
| <entry>Roman numeral (input between 1 and 3999)</entry> |
| </row> |
| <row> |
| <entry><literal>TH</literal> or <literal>th</literal></entry> |
| <entry>ordinal number suffix</entry> |
| </row> |
| <row> |
| <entry><literal>V</literal></entry> |
| <entry>shift specified number of digits (see notes)</entry> |
| </row> |
| <row> |
| <entry><literal>EEEE</literal></entry> |
| <entry>exponent for scientific notation</entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| Usage notes for numeric formatting: |
| |
| <itemizedlist> |
| <listitem> |
| <para> |
| <literal>0</literal> specifies a digit position that will always be printed, |
| even if it contains a leading/trailing zero. <literal>9</literal> also |
| specifies a digit position, but if it is a leading zero then it will |
| be replaced by a space, while if it is a trailing zero and fill mode |
| is specified then it will be deleted. (For <function>to_number()</function>, |
| these two pattern characters are equivalent.) |
| </para> |
| </listitem> |
| |
| <listitem> |
| <para> |
| The pattern characters <literal>S</literal>, <literal>L</literal>, <literal>D</literal>, |
| and <literal>G</literal> represent the sign, currency symbol, decimal point, |
| and thousands separator characters defined by the current locale |
| (see <xref linkend="guc-lc-monetary"/> |
| and <xref linkend="guc-lc-numeric"/>). The pattern characters period |
| and comma represent those exact characters, with the meanings of |
| decimal point and thousands separator, regardless of locale. |
| </para> |
| </listitem> |
| |
| <listitem> |
| <para> |
| If no explicit provision is made for a sign |
| in <function>to_char()</function>'s pattern, one column will be reserved for |
| the sign, and it will be anchored to (appear just left of) the |
| number. If <literal>S</literal> appears just left of some <literal>9</literal>'s, |
| it will likewise be anchored to the number. |
| </para> |
| </listitem> |
| |
| <listitem> |
| <para> |
| A sign formatted using <literal>SG</literal>, <literal>PL</literal>, or |
| <literal>MI</literal> is not anchored to |
| the number; for example, |
| <literal>to_char(-12, 'MI9999')</literal> produces <literal>'- 12'</literal> |
| but <literal>to_char(-12, 'S9999')</literal> produces <literal>' -12'</literal>. |
| (The Oracle implementation does not allow the use of |
| <literal>MI</literal> before <literal>9</literal>, but rather |
| requires that <literal>9</literal> precede |
| <literal>MI</literal>.) |
| </para> |
| </listitem> |
| |
| <listitem> |
| <para> |
| <literal>TH</literal> does not convert values less than zero |
| and does not convert fractional numbers. |
| </para> |
| </listitem> |
| |
| <listitem> |
| <para> |
| <literal>PL</literal>, <literal>SG</literal>, and |
| <literal>TH</literal> are <productname>PostgreSQL</productname> |
| extensions. |
| </para> |
| </listitem> |
| |
| <listitem> |
| <para> |
| In <function>to_number</function>, if non-data template patterns such |
| as <literal>L</literal> or <literal>TH</literal> are used, the |
| corresponding number of input characters are skipped, whether or not |
| they match the template pattern, unless they are data characters |
| (that is, digits, sign, decimal point, or comma). For |
| example, <literal>TH</literal> would skip two non-data characters. |
| </para> |
| </listitem> |
| |
| <listitem> |
| <para> |
| <literal>V</literal> with <function>to_char</function> |
| multiplies the input values by |
| <literal>10^<replaceable>n</replaceable></literal>, where |
| <replaceable>n</replaceable> is the number of digits following |
| <literal>V</literal>. <literal>V</literal> with |
| <function>to_number</function> divides in a similar manner. |
| <function>to_char</function> and <function>to_number</function> |
| do not support the use of |
| <literal>V</literal> combined with a decimal point |
| (e.g., <literal>99.9V99</literal> is not allowed). |
| </para> |
| </listitem> |
| |
| <listitem> |
| <para> |
| <literal>EEEE</literal> (scientific notation) cannot be used in |
| combination with any of the other formatting patterns or |
| modifiers other than digit and decimal point patterns, and must be at the end of the format string |
| (e.g., <literal>9.99EEEE</literal> is a valid pattern). |
| </para> |
| </listitem> |
| </itemizedlist> |
| </para> |
| |
| <para> |
| Certain modifiers can be applied to any template pattern to alter its |
| behavior. For example, <literal>FM99.99</literal> |
| is the <literal>99.99</literal> pattern with the |
| <literal>FM</literal> modifier. |
| <xref linkend="functions-formatting-numericmod-table"/> shows the |
| modifier patterns for numeric formatting. |
| </para> |
| |
| <table id="functions-formatting-numericmod-table"> |
| <title>Template Pattern Modifiers for Numeric Formatting</title> |
| <tgroup cols="3"> |
| <thead> |
| <row> |
| <entry>Modifier</entry> |
| <entry>Description</entry> |
| <entry>Example</entry> |
| </row> |
| </thead> |
| <tbody> |
| <row> |
| <entry><literal>FM</literal> prefix</entry> |
| <entry>fill mode (suppress trailing zeroes and padding blanks)</entry> |
| <entry><literal>FM99.99</literal></entry> |
| </row> |
| <row> |
| <entry><literal>TH</literal> suffix</entry> |
| <entry>upper case ordinal number suffix</entry> |
| <entry><literal>999TH</literal></entry> |
| </row> |
| <row> |
| <entry><literal>th</literal> suffix</entry> |
| <entry>lower case ordinal number suffix</entry> |
| <entry><literal>999th</literal></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| <xref linkend="functions-formatting-examples-table"/> shows some |
| examples of the use of the <function>to_char</function> function. |
| </para> |
| |
| <table id="functions-formatting-examples-table"> |
| <title><function>to_char</function> Examples</title> |
| <tgroup cols="2"> |
| <thead> |
| <row> |
| <entry>Expression</entry> |
| <entry>Result</entry> |
| </row> |
| </thead> |
| <tbody> |
| <row> |
| <entry><literal>to_char(current_timestamp, 'Day, DD HH12:MI:SS')</literal></entry> |
| <entry><literal>'Tuesday , 06 05:39:18'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(current_timestamp, 'FMDay, FMDD HH12:MI:SS')</literal></entry> |
| <entry><literal>'Tuesday, 6 05:39:18'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(-0.1, '99.99')</literal></entry> |
| <entry><literal>' -.10'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(-0.1, 'FM9.99')</literal></entry> |
| <entry><literal>'-.1'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(-0.1, 'FM90.99')</literal></entry> |
| <entry><literal>'-0.1'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(0.1, '0.9')</literal></entry> |
| <entry><literal>' 0.1'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(12, '9990999.9')</literal></entry> |
| <entry><literal>' 0012.0'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(12, 'FM9990999.9')</literal></entry> |
| <entry><literal>'0012.'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(485, '999')</literal></entry> |
| <entry><literal>' 485'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(-485, '999')</literal></entry> |
| <entry><literal>'-485'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(485, '9 9 9')</literal></entry> |
| <entry><literal>' 4 8 5'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(1485, '9,999')</literal></entry> |
| <entry><literal>' 1,485'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(1485, '9G999')</literal></entry> |
| <entry><literal>' 1 485'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(148.5, '999.999')</literal></entry> |
| <entry><literal>' 148.500'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(148.5, 'FM999.999')</literal></entry> |
| <entry><literal>'148.5'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(148.5, 'FM999.990')</literal></entry> |
| <entry><literal>'148.500'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(148.5, '999D999')</literal></entry> |
| <entry><literal>' 148,500'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(3148.5, '9G999D999')</literal></entry> |
| <entry><literal>' 3 148,500'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(-485, '999S')</literal></entry> |
| <entry><literal>'485-'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(-485, '999MI')</literal></entry> |
| <entry><literal>'485-'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(485, '999MI')</literal></entry> |
| <entry><literal>'485 '</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(485, 'FM999MI')</literal></entry> |
| <entry><literal>'485'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(485, 'PL999')</literal></entry> |
| <entry><literal>'+485'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(485, 'SG999')</literal></entry> |
| <entry><literal>'+485'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(-485, 'SG999')</literal></entry> |
| <entry><literal>'-485'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(-485, '9SG99')</literal></entry> |
| <entry><literal>'4-85'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(-485, '999PR')</literal></entry> |
| <entry><literal>'<485>'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(485, 'L999')</literal></entry> |
| <entry><literal>'DM 485'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(485, 'RN')</literal></entry> |
| <entry><literal>' CDLXXXV'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(485, 'FMRN')</literal></entry> |
| <entry><literal>'CDLXXXV'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(5.2, 'FMRN')</literal></entry> |
| <entry><literal>'V'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(482, '999th')</literal></entry> |
| <entry><literal>' 482nd'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(485, '"Good number:"999')</literal></entry> |
| <entry><literal>'Good number: 485'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(485.8, '"Pre:"999" Post:" .999')</literal></entry> |
| <entry><literal>'Pre: 485 Post: .800'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(12, '99V999')</literal></entry> |
| <entry><literal>' 12000'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(12.4, '99V999')</literal></entry> |
| <entry><literal>' 12400'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(12.45, '99V9')</literal></entry> |
| <entry><literal>' 125'</literal></entry> |
| </row> |
| <row> |
| <entry><literal>to_char(0.0004859, '9.99EEEE')</literal></entry> |
| <entry><literal>' 4.86e-04'</literal></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| </sect1> |
| |
| |
| <sect1 id="functions-datetime"> |
| <title>Date/Time Functions and Operators</title> |
| |
| <para> |
| <xref linkend="functions-datetime-table"/> shows the available |
| functions for date/time value processing, with details appearing in |
| the following subsections. <xref |
| linkend="operators-datetime-table"/> illustrates the behaviors of |
| the basic arithmetic operators (<literal>+</literal>, |
| <literal>*</literal>, etc.). For formatting functions, refer to |
| <xref linkend="functions-formatting"/>. You should be familiar with |
| the background information on date/time data types from <xref |
| linkend="datatype-datetime"/>. |
| </para> |
| |
| <para> |
| In addition, the usual comparison operators shown in |
| <xref linkend="functions-comparison-op-table"/> are available for the |
| date/time types. Dates and timestamps (with or without time zone) are |
| all comparable, while times (with or without time zone) and intervals |
| can only be compared to other values of the same data type. When |
| comparing a timestamp without time zone to a timestamp with time zone, |
| the former value is assumed to be given in the time zone specified by |
| the <xref linkend="guc-timezone"/> configuration parameter, and is |
| rotated to UTC for comparison to the latter value (which is already |
| in UTC internally). Similarly, a date value is assumed to represent |
| midnight in the <varname>TimeZone</varname> zone when comparing it |
| to a timestamp. |
| </para> |
| |
| <para> |
| All the functions and operators described below that take <type>time</type> or <type>timestamp</type> |
| inputs actually come in two variants: one that takes <type>time with time zone</type> or <type>timestamp |
| with time zone</type>, and one that takes <type>time without time zone</type> or <type>timestamp without time zone</type>. |
| For brevity, these variants are not shown separately. Also, the |
| <literal>+</literal> and <literal>*</literal> operators come in commutative pairs (for |
| example both <type>date</type> <literal>+</literal> <type>integer</type> |
| and <type>integer</type> <literal>+</literal> <type>date</type>); we show |
| only one of each such pair. |
| </para> |
| |
| <table id="operators-datetime-table"> |
| <title>Date/Time Operators</title> |
| |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Operator |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>date</type> <literal>+</literal> <type>integer</type> |
| <returnvalue>date</returnvalue> |
| </para> |
| <para> |
| Add a number of days to a date |
| </para> |
| <para> |
| <literal>date '2001-09-28' + 7</literal> |
| <returnvalue>2001-10-05</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>date</type> <literal>+</literal> <type>interval</type> |
| <returnvalue>timestamp</returnvalue> |
| </para> |
| <para> |
| Add an interval to a date |
| </para> |
| <para> |
| <literal>date '2001-09-28' + interval '1 hour'</literal> |
| <returnvalue>2001-09-28 01:00:00</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>date</type> <literal>+</literal> <type>time</type> |
| <returnvalue>timestamp</returnvalue> |
| </para> |
| <para> |
| Add a time-of-day to a date |
| </para> |
| <para> |
| <literal>date '2001-09-28' + time '03:00'</literal> |
| <returnvalue>2001-09-28 03:00:00</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>interval</type> <literal>+</literal> <type>interval</type> |
| <returnvalue>interval</returnvalue> |
| </para> |
| <para> |
| Add intervals |
| </para> |
| <para> |
| <literal>interval '1 day' + interval '1 hour'</literal> |
| <returnvalue>1 day 01:00:00</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>timestamp</type> <literal>+</literal> <type>interval</type> |
| <returnvalue>timestamp</returnvalue> |
| </para> |
| <para> |
| Add an interval to a timestamp |
| </para> |
| <para> |
| <literal>timestamp '2001-09-28 01:00' + interval '23 hours'</literal> |
| <returnvalue>2001-09-29 00:00:00</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>time</type> <literal>+</literal> <type>interval</type> |
| <returnvalue>time</returnvalue> |
| </para> |
| <para> |
| Add an interval to a time |
| </para> |
| <para> |
| <literal>time '01:00' + interval '3 hours'</literal> |
| <returnvalue>04:00:00</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <literal>-</literal> <type>interval</type> |
| <returnvalue>interval</returnvalue> |
| </para> |
| <para> |
| Negate an interval |
| </para> |
| <para> |
| <literal>- interval '23 hours'</literal> |
| <returnvalue>-23:00:00</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>date</type> <literal>-</literal> <type>date</type> |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Subtract dates, producing the number of days elapsed |
| </para> |
| <para> |
| <literal>date '2001-10-01' - date '2001-09-28'</literal> |
| <returnvalue>3</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>date</type> <literal>-</literal> <type>integer</type> |
| <returnvalue>date</returnvalue> |
| </para> |
| <para> |
| Subtract a number of days from a date |
| </para> |
| <para> |
| <literal>date '2001-10-01' - 7</literal> |
| <returnvalue>2001-09-24</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>date</type> <literal>-</literal> <type>interval</type> |
| <returnvalue>timestamp</returnvalue> |
| </para> |
| <para> |
| Subtract an interval from a date |
| </para> |
| <para> |
| <literal>date '2001-09-28' - interval '1 hour'</literal> |
| <returnvalue>2001-09-27 23:00:00</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>time</type> <literal>-</literal> <type>time</type> |
| <returnvalue>interval</returnvalue> |
| </para> |
| <para> |
| Subtract times |
| </para> |
| <para> |
| <literal>time '05:00' - time '03:00'</literal> |
| <returnvalue>02:00:00</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>time</type> <literal>-</literal> <type>interval</type> |
| <returnvalue>time</returnvalue> |
| </para> |
| <para> |
| Subtract an interval from a time |
| </para> |
| <para> |
| <literal>time '05:00' - interval '2 hours'</literal> |
| <returnvalue>03:00:00</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>timestamp</type> <literal>-</literal> <type>interval</type> |
| <returnvalue>timestamp</returnvalue> |
| </para> |
| <para> |
| Subtract an interval from a timestamp |
| </para> |
| <para> |
| <literal>timestamp '2001-09-28 23:00' - interval '23 hours'</literal> |
| <returnvalue>2001-09-28 00:00:00</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>interval</type> <literal>-</literal> <type>interval</type> |
| <returnvalue>interval</returnvalue> |
| </para> |
| <para> |
| Subtract intervals |
| </para> |
| <para> |
| <literal>interval '1 day' - interval '1 hour'</literal> |
| <returnvalue>1 day -01:00:00</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>timestamp</type> <literal>-</literal> <type>timestamp</type> |
| <returnvalue>interval</returnvalue> |
| </para> |
| <para> |
| Subtract timestamps (converting 24-hour intervals into days, |
| similarly to <function>justify_hours()</function>) |
| </para> |
| <para> |
| <literal>timestamp '2001-09-29 03:00' - timestamp '2001-07-27 12:00'</literal> |
| <returnvalue>63 days 15:00:00</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>interval</type> <literal>*</literal> <type>double precision</type> |
| <returnvalue>interval</returnvalue> |
| </para> |
| <para> |
| Multiply an interval by a scalar |
| </para> |
| <para> |
| <literal>interval '1 second' * 900</literal> |
| <returnvalue>00:15:00</returnvalue> |
| </para> |
| <para> |
| <literal>interval '1 day' * 21</literal> |
| <returnvalue>21 days</returnvalue> |
| </para> |
| <para> |
| <literal>interval '1 hour' * 3.5</literal> |
| <returnvalue>03:30:00</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>interval</type> <literal>/</literal> <type>double precision</type> |
| <returnvalue>interval</returnvalue> |
| </para> |
| <para> |
| Divide an interval by a scalar |
| </para> |
| <para> |
| <literal>interval '1 hour' / 1.5</literal> |
| <returnvalue>00:40:00</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <table id="functions-datetime-table"> |
| <title>Date/Time Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>age</primary> |
| </indexterm> |
| <function>age</function> ( <type>timestamp</type>, <type>timestamp</type> ) |
| <returnvalue>interval</returnvalue> |
| </para> |
| <para> |
| Subtract arguments, producing a <quote>symbolic</quote> result that |
| uses years and months, rather than just days |
| </para> |
| <para> |
| <literal>age(timestamp '2001-04-10', timestamp '1957-06-13')</literal> |
| <returnvalue>43 years 9 mons 27 days</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>age</function> ( <type>timestamp</type> ) |
| <returnvalue>interval</returnvalue> |
| </para> |
| <para> |
| Subtract argument from <function>current_date</function> (at midnight) |
| </para> |
| <para> |
| <literal>age(timestamp '1957-06-13')</literal> |
| <returnvalue>62 years 6 mons 10 days</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>clock_timestamp</primary> |
| </indexterm> |
| <function>clock_timestamp</function> ( ) |
| <returnvalue>timestamp with time zone</returnvalue> |
| </para> |
| <para> |
| Current date and time (changes during statement execution); |
| see <xref linkend="functions-datetime-current"/> |
| </para> |
| <para> |
| <literal>clock_timestamp()</literal> |
| <returnvalue>2019-12-23 14:39:53.662522-05</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>current_date</primary> |
| </indexterm> |
| <function>current_date</function> |
| <returnvalue>date</returnvalue> |
| </para> |
| <para> |
| Current date; see <xref linkend="functions-datetime-current"/> |
| </para> |
| <para> |
| <literal>current_date</literal> |
| <returnvalue>2019-12-23</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>current_time</primary> |
| </indexterm> |
| <function>current_time</function> |
| <returnvalue>time with time zone</returnvalue> |
| </para> |
| <para> |
| Current time of day; see <xref linkend="functions-datetime-current"/> |
| </para> |
| <para> |
| <literal>current_time</literal> |
| <returnvalue>14:39:53.662522-05</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>current_time</function> ( <type>integer</type> ) |
| <returnvalue>time with time zone</returnvalue> |
| </para> |
| <para> |
| Current time of day, with limited precision; |
| see <xref linkend="functions-datetime-current"/> |
| </para> |
| <para> |
| <literal>current_time(2)</literal> |
| <returnvalue>14:39:53.66-05</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>current_timestamp</primary> |
| </indexterm> |
| <function>current_timestamp</function> |
| <returnvalue>timestamp with time zone</returnvalue> |
| </para> |
| <para> |
| Current date and time (start of current transaction); |
| see <xref linkend="functions-datetime-current"/> |
| </para> |
| <para> |
| <literal>current_timestamp</literal> |
| <returnvalue>2019-12-23 14:39:53.662522-05</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>current_timestamp</function> ( <type>integer</type> ) |
| <returnvalue>timestamp with time zone</returnvalue> |
| </para> |
| <para> |
| Current date and time (start of current transaction), with limited precision; |
| see <xref linkend="functions-datetime-current"/> |
| </para> |
| <para> |
| <literal>current_timestamp(0)</literal> |
| <returnvalue>2019-12-23 14:39:53-05</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>date_bin</function> ( <type>interval</type>, <type>timestamp</type>, <type>timestamp</type> ) |
| <returnvalue>timestamp</returnvalue> |
| </para> |
| <para> |
| Bin input into specified interval aligned with specified origin; see <xref linkend="functions-datetime-bin"/> |
| </para> |
| <para> |
| <literal>date_bin('15 minutes', timestamp '2001-02-16 20:38:40', timestamp '2001-02-16 20:05:00')</literal> |
| <returnvalue>2001-02-16 20:35:00</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>date_part</primary> |
| </indexterm> |
| <function>date_part</function> ( <type>text</type>, <type>timestamp</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Get timestamp subfield (equivalent to <function>extract</function>); |
| see <xref linkend="functions-datetime-extract"/> |
| </para> |
| <para> |
| <literal>date_part('hour', timestamp '2001-02-16 20:38:40')</literal> |
| <returnvalue>20</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>date_part</function> ( <type>text</type>, <type>interval</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Get interval subfield (equivalent to <function>extract</function>); |
| see <xref linkend="functions-datetime-extract"/> |
| </para> |
| <para> |
| <literal>date_part('month', interval '2 years 3 months')</literal> |
| <returnvalue>3</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>date_trunc</primary> |
| </indexterm> |
| <function>date_trunc</function> ( <type>text</type>, <type>timestamp</type> ) |
| <returnvalue>timestamp</returnvalue> |
| </para> |
| <para> |
| Truncate to specified precision; see <xref linkend="functions-datetime-trunc"/> |
| </para> |
| <para> |
| <literal>date_trunc('hour', timestamp '2001-02-16 20:38:40')</literal> |
| <returnvalue>2001-02-16 20:00:00</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>date_trunc</function> ( <type>text</type>, <type>timestamp with time zone</type>, <type>text</type> ) |
| <returnvalue>timestamp with time zone</returnvalue> |
| </para> |
| <para> |
| Truncate to specified precision in the specified time zone; see |
| <xref linkend="functions-datetime-trunc"/> |
| </para> |
| <para> |
| <literal>date_trunc('day', timestamptz '2001-02-16 20:38:40+00', 'Australia/Sydney')</literal> |
| <returnvalue>2001-02-16 13:00:00+00</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>date_trunc</function> ( <type>text</type>, <type>interval</type> ) |
| <returnvalue>interval</returnvalue> |
| </para> |
| <para> |
| Truncate to specified precision; see |
| <xref linkend="functions-datetime-trunc"/> |
| </para> |
| <para> |
| <literal>date_trunc('hour', interval '2 days 3 hours 40 minutes')</literal> |
| <returnvalue>2 days 03:00:00</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>extract</primary> |
| </indexterm> |
| <function>extract</function> ( <parameter>field</parameter> <literal>from</literal> <type>timestamp</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para> |
| Get timestamp subfield; see <xref linkend="functions-datetime-extract"/> |
| </para> |
| <para> |
| <literal>extract(hour from timestamp '2001-02-16 20:38:40')</literal> |
| <returnvalue>20</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>extract</function> ( <parameter>field</parameter> <literal>from</literal> <type>interval</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para> |
| Get interval subfield; see <xref linkend="functions-datetime-extract"/> |
| </para> |
| <para> |
| <literal>extract(month from interval '2 years 3 months')</literal> |
| <returnvalue>3</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>isfinite</primary> |
| </indexterm> |
| <function>isfinite</function> ( <type>date</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Test for finite date (not +/-infinity) |
| </para> |
| <para> |
| <literal>isfinite(date '2001-02-16')</literal> |
| <returnvalue>true</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>isfinite</function> ( <type>timestamp</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Test for finite timestamp (not +/-infinity) |
| </para> |
| <para> |
| <literal>isfinite(timestamp 'infinity')</literal> |
| <returnvalue>false</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>isfinite</function> ( <type>interval</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Test for finite interval (currently always true) |
| </para> |
| <para> |
| <literal>isfinite(interval '4 hours')</literal> |
| <returnvalue>true</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>justify_days</primary> |
| </indexterm> |
| <function>justify_days</function> ( <type>interval</type> ) |
| <returnvalue>interval</returnvalue> |
| </para> |
| <para> |
| Adjust interval so 30-day time periods are represented as months |
| </para> |
| <para> |
| <literal>justify_days(interval '35 days')</literal> |
| <returnvalue>1 mon 5 days</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>justify_hours</primary> |
| </indexterm> |
| <function>justify_hours</function> ( <type>interval</type> ) |
| <returnvalue>interval</returnvalue> |
| </para> |
| <para> |
| Adjust interval so 24-hour time periods are represented as days |
| </para> |
| <para> |
| <literal>justify_hours(interval '27 hours')</literal> |
| <returnvalue>1 day 03:00:00</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>justify_interval</primary> |
| </indexterm> |
| <function>justify_interval</function> ( <type>interval</type> ) |
| <returnvalue>interval</returnvalue> |
| </para> |
| <para> |
| Adjust interval using <function>justify_days</function> |
| and <function>justify_hours</function>, with additional sign |
| adjustments |
| </para> |
| <para> |
| <literal>justify_interval(interval '1 mon -1 hour')</literal> |
| <returnvalue>29 days 23:00:00</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>localtime</primary> |
| </indexterm> |
| <function>localtime</function> |
| <returnvalue>time</returnvalue> |
| </para> |
| <para> |
| Current time of day; |
| see <xref linkend="functions-datetime-current"/> |
| </para> |
| <para> |
| <literal>localtime</literal> |
| <returnvalue>14:39:53.662522</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>localtime</function> ( <type>integer</type> ) |
| <returnvalue>time</returnvalue> |
| </para> |
| <para> |
| Current time of day, with limited precision; |
| see <xref linkend="functions-datetime-current"/> |
| </para> |
| <para> |
| <literal>localtime(0)</literal> |
| <returnvalue>14:39:53</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>localtimestamp</primary> |
| </indexterm> |
| <function>localtimestamp</function> |
| <returnvalue>timestamp</returnvalue> |
| </para> |
| <para> |
| Current date and time (start of current transaction); |
| see <xref linkend="functions-datetime-current"/> |
| </para> |
| <para> |
| <literal>localtimestamp</literal> |
| <returnvalue>2019-12-23 14:39:53.662522</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>localtimestamp</function> ( <type>integer</type> ) |
| <returnvalue>timestamp</returnvalue> |
| </para> |
| <para> |
| Current date and time (start of current |
| transaction), with limited precision; |
| see <xref linkend="functions-datetime-current"/> |
| </para> |
| <para> |
| <literal>localtimestamp(2)</literal> |
| <returnvalue>2019-12-23 14:39:53.66</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>make_date</primary> |
| </indexterm> |
| <function>make_date</function> ( <parameter>year</parameter> <type>int</type>, |
| <parameter>month</parameter> <type>int</type>, |
| <parameter>day</parameter> <type>int</type> ) |
| <returnvalue>date</returnvalue> |
| </para> |
| <para> |
| Create date from year, month and day fields |
| (negative years signify BC) |
| </para> |
| <para> |
| <literal>make_date(2013, 7, 15)</literal> |
| <returnvalue>2013-07-15</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"><indexterm> |
| <primary>make_interval</primary> |
| </indexterm> |
| <function>make_interval</function> ( <optional> <parameter>years</parameter> <type>int</type> |
| <optional>, <parameter>months</parameter> <type>int</type> |
| <optional>, <parameter>weeks</parameter> <type>int</type> |
| <optional>, <parameter>days</parameter> <type>int</type> |
| <optional>, <parameter>hours</parameter> <type>int</type> |
| <optional>, <parameter>mins</parameter> <type>int</type> |
| <optional>, <parameter>secs</parameter> <type>double precision</type> |
| </optional></optional></optional></optional></optional></optional></optional> ) |
| <returnvalue>interval</returnvalue> |
| </para> |
| <para> |
| Create interval from years, months, weeks, days, hours, minutes and |
| seconds fields, each of which can default to zero |
| </para> |
| <para> |
| <literal>make_interval(days => 10)</literal> |
| <returnvalue>10 days</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>make_time</primary> |
| </indexterm> |
| <function>make_time</function> ( <parameter>hour</parameter> <type>int</type>, |
| <parameter>min</parameter> <type>int</type>, |
| <parameter>sec</parameter> <type>double precision</type> ) |
| <returnvalue>time</returnvalue> |
| </para> |
| <para> |
| Create time from hour, minute and seconds fields |
| </para> |
| <para> |
| <literal>make_time(8, 15, 23.5)</literal> |
| <returnvalue>08:15:23.5</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>make_timestamp</primary> |
| </indexterm> |
| <function>make_timestamp</function> ( <parameter>year</parameter> <type>int</type>, |
| <parameter>month</parameter> <type>int</type>, |
| <parameter>day</parameter> <type>int</type>, |
| <parameter>hour</parameter> <type>int</type>, |
| <parameter>min</parameter> <type>int</type>, |
| <parameter>sec</parameter> <type>double precision</type> ) |
| <returnvalue>timestamp</returnvalue> |
| </para> |
| <para> |
| Create timestamp from year, month, day, hour, minute and seconds fields |
| (negative years signify BC) |
| </para> |
| <para> |
| <literal>make_timestamp(2013, 7, 15, 8, 15, 23.5)</literal> |
| <returnvalue>2013-07-15 08:15:23.5</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>make_timestamptz</primary> |
| </indexterm> |
| <function>make_timestamptz</function> ( <parameter>year</parameter> <type>int</type>, |
| <parameter>month</parameter> <type>int</type>, |
| <parameter>day</parameter> <type>int</type>, |
| <parameter>hour</parameter> <type>int</type>, |
| <parameter>min</parameter> <type>int</type>, |
| <parameter>sec</parameter> <type>double precision</type> |
| <optional>, <parameter>timezone</parameter> <type>text</type> </optional> ) |
| <returnvalue>timestamp with time zone</returnvalue> |
| </para> |
| <para> |
| Create timestamp with time zone from year, month, day, hour, minute |
| and seconds fields (negative years signify BC). |
| If <parameter>timezone</parameter> is not |
| specified, the current time zone is used; the examples assume the |
| session time zone is <literal>Europe/London</literal> |
| </para> |
| <para> |
| <literal>make_timestamptz(2013, 7, 15, 8, 15, 23.5)</literal> |
| <returnvalue>2013-07-15 08:15:23.5+01</returnvalue> |
| </para> |
| <para> |
| <literal>make_timestamptz(2013, 7, 15, 8, 15, 23.5, 'America/New_York')</literal> |
| <returnvalue>2013-07-15 13:15:23.5+01</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>now</primary> |
| </indexterm> |
| <function>now</function> ( ) |
| <returnvalue>timestamp with time zone</returnvalue> |
| </para> |
| <para> |
| Current date and time (start of current transaction); |
| see <xref linkend="functions-datetime-current"/> |
| </para> |
| <para> |
| <literal>now()</literal> |
| <returnvalue>2019-12-23 14:39:53.662522-05</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>statement_timestamp</primary> |
| </indexterm> |
| <function>statement_timestamp</function> ( ) |
| <returnvalue>timestamp with time zone</returnvalue> |
| </para> |
| <para> |
| Current date and time (start of current statement); |
| see <xref linkend="functions-datetime-current"/> |
| </para> |
| <para> |
| <literal>statement_timestamp()</literal> |
| <returnvalue>2019-12-23 14:39:53.662522-05</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>timeofday</primary> |
| </indexterm> |
| <function>timeofday</function> ( ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Current date and time |
| (like <function>clock_timestamp</function>, but as a <type>text</type> string); |
| see <xref linkend="functions-datetime-current"/> |
| </para> |
| <para> |
| <literal>timeofday()</literal> |
| <returnvalue>Mon Dec 23 14:39:53.662522 2019 EST</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>transaction_timestamp</primary> |
| </indexterm> |
| <function>transaction_timestamp</function> ( ) |
| <returnvalue>timestamp with time zone</returnvalue> |
| </para> |
| <para> |
| Current date and time (start of current transaction); |
| see <xref linkend="functions-datetime-current"/> |
| </para> |
| <para> |
| <literal>transaction_timestamp()</literal> |
| <returnvalue>2019-12-23 14:39:53.662522-05</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>to_timestamp</primary> |
| </indexterm> |
| <function>to_timestamp</function> ( <type>double precision</type> ) |
| <returnvalue>timestamp with time zone</returnvalue> |
| </para> |
| <para> |
| Convert Unix epoch (seconds since 1970-01-01 00:00:00+00) to |
| timestamp with time zone |
| </para> |
| <para> |
| <literal>to_timestamp(1284352323)</literal> |
| <returnvalue>2010-09-13 04:32:03+00</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| <indexterm> |
| <primary>OVERLAPS</primary> |
| </indexterm> |
| In addition to these functions, the SQL <literal>OVERLAPS</literal> operator is |
| supported: |
| <synopsis> |
| (<replaceable>start1</replaceable>, <replaceable>end1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>end2</replaceable>) |
| (<replaceable>start1</replaceable>, <replaceable>length1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>length2</replaceable>) |
| </synopsis> |
| This expression yields true when two time periods (defined by their |
| endpoints) overlap, false when they do not overlap. The endpoints |
| can be specified as pairs of dates, times, or time stamps; or as |
| a date, time, or time stamp followed by an interval. When a pair |
| of values is provided, either the start or the end can be written |
| first; <literal>OVERLAPS</literal> automatically takes the earlier value |
| of the pair as the start. Each time period is considered to |
| represent the half-open interval <replaceable>start</replaceable> <literal><=</literal> |
| <replaceable>time</replaceable> <literal><</literal> <replaceable>end</replaceable>, unless |
| <replaceable>start</replaceable> and <replaceable>end</replaceable> are equal in which case it |
| represents that single time instant. This means for instance that two |
| time periods with only an endpoint in common do not overlap. |
| </para> |
| |
| <screen> |
| SELECT (DATE '2001-02-16', DATE '2001-12-21') OVERLAPS |
| (DATE '2001-10-30', DATE '2002-10-30'); |
| <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput> |
| SELECT (DATE '2001-02-16', INTERVAL '100 days') OVERLAPS |
| (DATE '2001-10-30', DATE '2002-10-30'); |
| <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput> |
| SELECT (DATE '2001-10-29', DATE '2001-10-30') OVERLAPS |
| (DATE '2001-10-30', DATE '2001-10-31'); |
| <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput> |
| SELECT (DATE '2001-10-30', DATE '2001-10-30') OVERLAPS |
| (DATE '2001-10-30', DATE '2001-10-31'); |
| <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput> |
| </screen> |
| |
| <para> |
| When adding an <type>interval</type> value to (or subtracting an |
| <type>interval</type> value from) a <type>timestamp with time zone</type> |
| value, the days component advances or decrements the date of the |
| <type>timestamp with time zone</type> by the indicated number of days, |
| keeping the time of day the same. |
| Across daylight saving time changes (when the session time zone is set to a |
| time zone that recognizes DST), this means <literal>interval '1 day'</literal> |
| does not necessarily equal <literal>interval '24 hours'</literal>. |
| For example, with the session time zone set |
| to <literal>America/Denver</literal>: |
| <screen> |
| SELECT timestamp with time zone '2005-04-02 12:00:00-07' + interval '1 day'; |
| <lineannotation>Result: </lineannotation><computeroutput>2005-04-03 12:00:00-06</computeroutput> |
| SELECT timestamp with time zone '2005-04-02 12:00:00-07' + interval '24 hours'; |
| <lineannotation>Result: </lineannotation><computeroutput>2005-04-03 13:00:00-06</computeroutput> |
| </screen> |
| This happens because an hour was skipped due to a change in daylight saving |
| time at <literal>2005-04-03 02:00:00</literal> in time zone |
| <literal>America/Denver</literal>. |
| </para> |
| |
| <para> |
| Note there can be ambiguity in the <literal>months</literal> field returned by |
| <function>age</function> because different months have different numbers of |
| days. <productname>PostgreSQL</productname>'s approach uses the month from the |
| earlier of the two dates when calculating partial months. For example, |
| <literal>age('2004-06-01', '2004-04-30')</literal> uses April to yield |
| <literal>1 mon 1 day</literal>, while using May would yield <literal>1 mon 2 |
| days</literal> because May has 31 days, while April has only 30. |
| </para> |
| |
| <para> |
| Subtraction of dates and timestamps can also be complex. One conceptually |
| simple way to perform subtraction is to convert each value to a number |
| of seconds using <literal>EXTRACT(EPOCH FROM ...)</literal>, then subtract the |
| results; this produces the |
| number of <emphasis>seconds</emphasis> between the two values. This will adjust |
| for the number of days in each month, timezone changes, and daylight |
| saving time adjustments. Subtraction of date or timestamp |
| values with the <quote><literal>-</literal></quote> operator |
| returns the number of days (24-hours) and hours/minutes/seconds |
| between the values, making the same adjustments. The <function>age</function> |
| function returns years, months, days, and hours/minutes/seconds, |
| performing field-by-field subtraction and then adjusting for negative |
| field values. The following queries illustrate the differences in these |
| approaches. The sample results were produced with <literal>timezone |
| = 'US/Eastern'</literal>; there is a daylight saving time change between the |
| two dates used: |
| </para> |
| |
| <screen> |
| SELECT EXTRACT(EPOCH FROM timestamptz '2013-07-01 12:00:00') - |
| EXTRACT(EPOCH FROM timestamptz '2013-03-01 12:00:00'); |
| <lineannotation>Result: </lineannotation><computeroutput>10537200</computeroutput> |
| SELECT (EXTRACT(EPOCH FROM timestamptz '2013-07-01 12:00:00') - |
| EXTRACT(EPOCH FROM timestamptz '2013-03-01 12:00:00')) |
| / 60 / 60 / 24; |
| <lineannotation>Result: </lineannotation><computeroutput>121.958333333333</computeroutput> |
| SELECT timestamptz '2013-07-01 12:00:00' - timestamptz '2013-03-01 12:00:00'; |
| <lineannotation>Result: </lineannotation><computeroutput>121 days 23:00:00</computeroutput> |
| SELECT age(timestamptz '2013-07-01 12:00:00', timestamptz '2013-03-01 12:00:00'); |
| <lineannotation>Result: </lineannotation><computeroutput>4 mons</computeroutput> |
| </screen> |
| |
| <sect2 id="functions-datetime-extract"> |
| <title><function>EXTRACT</function>, <function>date_part</function></title> |
| |
| <indexterm> |
| <primary>date_part</primary> |
| </indexterm> |
| <indexterm> |
| <primary>extract</primary> |
| </indexterm> |
| |
| <synopsis> |
| EXTRACT(<replaceable>field</replaceable> FROM <replaceable>source</replaceable>) |
| </synopsis> |
| |
| <para> |
| The <function>extract</function> function retrieves subfields |
| such as year or hour from date/time values. |
| <replaceable>source</replaceable> must be a value expression of |
| type <type>timestamp</type>, <type>time</type>, or <type>interval</type>. |
| (Expressions of type <type>date</type> are |
| cast to <type>timestamp</type> and can therefore be used as |
| well.) <replaceable>field</replaceable> is an identifier or |
| string that selects what field to extract from the source value. |
| The <function>extract</function> function returns values of type |
| <type>numeric</type>. |
| The following are valid field names: |
| |
| <!-- alphabetical --> |
| <variablelist> |
| <varlistentry> |
| <term><literal>century</literal></term> |
| <listitem> |
| <para> |
| The century |
| </para> |
| |
| <screen> |
| SELECT EXTRACT(CENTURY FROM TIMESTAMP '2000-12-16 12:21:13'); |
| <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput> |
| SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40'); |
| <lineannotation>Result: </lineannotation><computeroutput>21</computeroutput> |
| </screen> |
| |
| <para> |
| The first century starts at 0001-01-01 00:00:00 AD, although |
| they did not know it at the time. This definition applies to all |
| Gregorian calendar countries. There is no century number 0, |
| you go from -1 century to 1 century. |
| |
| If you disagree with this, please write your complaint to: |
| Pope, Cathedral Saint-Peter of Roma, Vatican. |
| </para> |
| </listitem> |
| </varlistentry> |
| |
| <varlistentry> |
| <term><literal>day</literal></term> |
| <listitem> |
| <para> |
| For <type>timestamp</type> values, the day (of the month) field |
| (1–31) ; for <type>interval</type> values, the number of days |
| </para> |
| |
| <screen> |
| SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40'); |
| <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput> |
| |
| SELECT EXTRACT(DAY FROM INTERVAL '40 days 1 minute'); |
| <lineannotation>Result: </lineannotation><computeroutput>40</computeroutput> |
| </screen> |
| |
| </listitem> |
| </varlistentry> |
| |
| <varlistentry> |
| <term><literal>decade</literal></term> |
| <listitem> |
| <para> |
| The year field divided by 10 |
| </para> |
| |
| <screen> |
| SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40'); |
| <lineannotation>Result: </lineannotation><computeroutput>200</computeroutput> |
| </screen> |
| </listitem> |
| </varlistentry> |
| |
| <varlistentry> |
| <term><literal>dow</literal></term> |
| <listitem> |
| <para> |
| The day of the week as Sunday (<literal>0</literal>) to |
| Saturday (<literal>6</literal>) |
| </para> |
| |
| <screen> |
| SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40'); |
| <lineannotation>Result: </lineannotation><computeroutput>5</computeroutput> |
| </screen> |
| <para> |
| Note that <function>extract</function>'s day of the week numbering |
| differs from that of the <function>to_char(..., |
| 'D')</function> function. |
| </para> |
| |
| </listitem> |
| </varlistentry> |
| |
| <varlistentry> |
| <term><literal>doy</literal></term> |
| <listitem> |
| <para> |
| The day of the year (1–365/366) |
| </para> |
| |
| <screen> |
| SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40'); |
| <lineannotation>Result: </lineannotation><computeroutput>47</computeroutput> |
| </screen> |
| </listitem> |
| </varlistentry> |
| |
| <varlistentry> |
| <term><literal>epoch</literal></term> |
| <listitem> |
| <para> |
| For <type>timestamp with time zone</type> values, the |
| number of seconds since 1970-01-01 00:00:00 UTC (negative for |
| timestamps before that); |
| for <type>date</type> and <type>timestamp</type> values, the |
| nominal number of seconds since 1970-01-01 00:00:00, |
| without regard to timezone or daylight-savings rules; |
| for <type>interval</type> values, the total number |
| of seconds in the interval |
| </para> |
| |
| <screen> |
| SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40.12-08'); |
| <lineannotation>Result: </lineannotation><computeroutput>982384720.12</computeroutput> |
| |
| SELECT EXTRACT(EPOCH FROM TIMESTAMP '2001-02-16 20:38:40.12'); |
| <lineannotation>Result: </lineannotation><computeroutput>982355920.12</computeroutput> |
| |
| SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours'); |
| <lineannotation>Result: </lineannotation><computeroutput>442800</computeroutput> |
| </screen> |
| |
| <para> |
| You can convert an epoch value back to a <type>timestamp with time zone</type> |
| with <function>to_timestamp</function>: |
| </para> |
| <screen> |
| SELECT to_timestamp(982384720.12); |
| <lineannotation>Result: </lineannotation><computeroutput>2001-02-17 04:38:40.12+00</computeroutput> |
| </screen> |
| |
| <para> |
| Beware that applying <function>to_timestamp</function> to an epoch |
| extracted from a <type>date</type> or <type>timestamp</type> value |
| could produce a misleading result: the result will effectively |
| assume that the original value had been given in UTC, which might |
| not be the case. |
| </para> |
| </listitem> |
| </varlistentry> |
| |
| <varlistentry> |
| <term><literal>hour</literal></term> |
| <listitem> |
| <para> |
| The hour field (0–23) |
| </para> |
| |
| <screen> |
| SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40'); |
| <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput> |
| </screen> |
| </listitem> |
| </varlistentry> |
| |
| <varlistentry> |
| <term><literal>isodow</literal></term> |
| <listitem> |
| <para> |
| The day of the week as Monday (<literal>1</literal>) to |
| Sunday (<literal>7</literal>) |
| </para> |
| |
| <screen> |
| SELECT EXTRACT(ISODOW FROM TIMESTAMP '2001-02-18 20:38:40'); |
| <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput> |
| </screen> |
| <para> |
| This is identical to <literal>dow</literal> except for Sunday. This |
| matches the <acronym>ISO</acronym> 8601 day of the week numbering. |
| </para> |
| |
| </listitem> |
| </varlistentry> |
| |
| <varlistentry> |
| <term><literal>isoyear</literal></term> |
| <listitem> |
| <para> |
| The <acronym>ISO</acronym> 8601 week-numbering year that the date |
| falls in (not applicable to intervals) |
| </para> |
| |
| <screen> |
| SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-01'); |
| <lineannotation>Result: </lineannotation><computeroutput>2005</computeroutput> |
| SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-02'); |
| <lineannotation>Result: </lineannotation><computeroutput>2006</computeroutput> |
| </screen> |
| |
| <para> |
| Each <acronym>ISO</acronym> 8601 week-numbering year begins with the |
| Monday of the week containing the 4th of January, so in early |
| January or late December the <acronym>ISO</acronym> year may be |
| different from the Gregorian year. See the <literal>week</literal> |
| field for more information. |
| </para> |
| <para> |
| This field is not available in PostgreSQL releases prior to 8.3. |
| </para> |
| </listitem> |
| </varlistentry> |
| |
| <varlistentry> |
| <term><literal>julian</literal></term> |
| <listitem> |
| <para> |
| The <firstterm>Julian Date</firstterm> corresponding to the |
| date or timestamp (not applicable to intervals). Timestamps |
| that are not local midnight result in a fractional value. See |
| <xref linkend="datetime-julian-dates"/> for more information. |
| </para> |
| |
| <screen> |
| SELECT EXTRACT(JULIAN FROM DATE '2006-01-01'); |
| <lineannotation>Result: </lineannotation><computeroutput>2453737</computeroutput> |
| SELECT EXTRACT(JULIAN FROM TIMESTAMP '2006-01-01 12:00'); |
| <lineannotation>Result: </lineannotation><computeroutput>2453737.50000000000000000000</computeroutput> |
| </screen> |
| </listitem> |
| </varlistentry> |
| |
| <varlistentry> |
| <term><literal>microseconds</literal></term> |
| <listitem> |
| <para> |
| The seconds field, including fractional parts, multiplied by 1 |
| 000 000; note that this includes full seconds |
| </para> |
| |
| <screen> |
| SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5'); |
| <lineannotation>Result: </lineannotation><computeroutput>28500000</computeroutput> |
| </screen> |
| </listitem> |
| </varlistentry> |
| |
| <varlistentry> |
| <term><literal>millennium</literal></term> |
| <listitem> |
| <para> |
| The millennium |
| </para> |
| |
| <screen> |
| SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40'); |
| <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput> |
| </screen> |
| |
| <para> |
| Years in the 1900s are in the second millennium. |
| The third millennium started January 1, 2001. |
| </para> |
| </listitem> |
| </varlistentry> |
| |
| <varlistentry> |
| <term><literal>milliseconds</literal></term> |
| <listitem> |
| <para> |
| The seconds field, including fractional parts, multiplied by |
| 1000. Note that this includes full seconds. |
| </para> |
| |
| <screen> |
| SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5'); |
| <lineannotation>Result: </lineannotation><computeroutput>28500</computeroutput> |
| </screen> |
| </listitem> |
| </varlistentry> |
| |
| <varlistentry> |
| <term><literal>minute</literal></term> |
| <listitem> |
| <para> |
| The minutes field (0–59) |
| </para> |
| |
| <screen> |
| SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40'); |
| <lineannotation>Result: </lineannotation><computeroutput>38</computeroutput> |
| </screen> |
| </listitem> |
| </varlistentry> |
| |
| <varlistentry> |
| <term><literal>month</literal></term> |
| <listitem> |
| <para> |
| For <type>timestamp</type> values, the number of the month |
| within the year (1–12) ; for <type>interval</type> values, |
| the number of months, modulo 12 (0–11) |
| </para> |
| |
| <screen> |
| SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40'); |
| <lineannotation>Result: </lineannotation><computeroutput>2</computeroutput> |
| |
| SELECT EXTRACT(MONTH FROM INTERVAL '2 years 3 months'); |
| <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput> |
| |
| SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months'); |
| <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput> |
| </screen> |
| </listitem> |
| </varlistentry> |
| |
| <varlistentry> |
| <term><literal>quarter</literal></term> |
| <listitem> |
| <para> |
| The quarter of the year (1–4) that the date is in |
| </para> |
| |
| <screen> |
| SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40'); |
| <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput> |
| </screen> |
| </listitem> |
| </varlistentry> |
| |
| <varlistentry> |
| <term><literal>second</literal></term> |
| <listitem> |
| <para> |
| The seconds field, including any fractional seconds |
| </para> |
| |
| <screen> |
| SELECT EXTRACT(SECOND FROM TIMESTAMP '2001-02-16 20:38:40'); |
| <lineannotation>Result: </lineannotation><computeroutput>40</computeroutput> |
| |
| SELECT EXTRACT(SECOND FROM TIME '17:12:28.5'); |
| <lineannotation>Result: </lineannotation><computeroutput>28.5</computeroutput> |
| </screen> |
| </listitem> |
| </varlistentry> |
| <varlistentry> |
| <term><literal>timezone</literal></term> |
| <listitem> |
| <para> |
| The time zone offset from UTC, measured in seconds. Positive values |
| correspond to time zones east of UTC, negative values to |
| zones west of UTC. (Technically, |
| <productname>PostgreSQL</productname> does not use UTC because |
| leap seconds are not handled.) |
| </para> |
| </listitem> |
| </varlistentry> |
| |
| <varlistentry> |
| <term><literal>timezone_hour</literal></term> |
| <listitem> |
| <para> |
| The hour component of the time zone offset |
| </para> |
| </listitem> |
| </varlistentry> |
| |
| <varlistentry> |
| <term><literal>timezone_minute</literal></term> |
| <listitem> |
| <para> |
| The minute component of the time zone offset |
| </para> |
| </listitem> |
| </varlistentry> |
| |
| <varlistentry> |
| <term><literal>week</literal></term> |
| <listitem> |
| <para> |
| The number of the <acronym>ISO</acronym> 8601 week-numbering week of |
| the year. By definition, ISO weeks start on Mondays and the first |
| week of a year contains January 4 of that year. In other words, the |
| first Thursday of a year is in week 1 of that year. |
| </para> |
| <para> |
| In the ISO week-numbering system, it is possible for early-January |
| dates to be part of the 52nd or 53rd week of the previous year, and for |
| late-December dates to be part of the first week of the next year. |
| For example, <literal>2005-01-01</literal> is part of the 53rd week of year |
| 2004, and <literal>2006-01-01</literal> is part of the 52nd week of year |
| 2005, while <literal>2012-12-31</literal> is part of the first week of 2013. |
| It's recommended to use the <literal>isoyear</literal> field together with |
| <literal>week</literal> to get consistent results. |
| </para> |
| |
| <screen> |
| SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40'); |
| <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput> |
| </screen> |
| </listitem> |
| </varlistentry> |
| |
| <varlistentry> |
| <term><literal>year</literal></term> |
| <listitem> |
| <para> |
| The year field. Keep in mind there is no <literal>0 AD</literal>, so subtracting |
| <literal>BC</literal> years from <literal>AD</literal> years should be done with care. |
| </para> |
| |
| <screen> |
| SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40'); |
| <lineannotation>Result: </lineannotation><computeroutput>2001</computeroutput> |
| </screen> |
| </listitem> |
| </varlistentry> |
| |
| </variablelist> |
| </para> |
| |
| <note> |
| <para> |
| When the input value is +/-Infinity, <function>extract</function> returns |
| +/-Infinity for monotonically-increasing fields (<literal>epoch</literal>, |
| <literal>julian</literal>, <literal>year</literal>, <literal>isoyear</literal>, |
| <literal>decade</literal>, <literal>century</literal>, and <literal>millennium</literal>). |
| For other fields, NULL is returned. <productname>PostgreSQL</productname> |
| versions before 9.6 returned zero for all cases of infinite input. |
| </para> |
| </note> |
| |
| <para> |
| The <function>extract</function> function is primarily intended |
| for computational processing. For formatting date/time values for |
| display, see <xref linkend="functions-formatting"/>. |
| </para> |
| |
| <para> |
| The <function>date_part</function> function is modeled on the traditional |
| <productname>Ingres</productname> equivalent to the |
| <acronym>SQL</acronym>-standard function <function>extract</function>: |
| <synopsis> |
| date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>) |
| </synopsis> |
| Note that here the <replaceable>field</replaceable> parameter needs to |
| be a string value, not a name. The valid field names for |
| <function>date_part</function> are the same as for |
| <function>extract</function>. |
| For historical reasons, the <function>date_part</function> function |
| returns values of type <type>double precision</type>. This can result in |
| a loss of precision in certain uses. Using <function>extract</function> |
| is recommended instead. |
| </para> |
| |
| <screen> |
| SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40'); |
| <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput> |
| |
| SELECT date_part('hour', INTERVAL '4 hours 3 minutes'); |
| <lineannotation>Result: </lineannotation><computeroutput>4</computeroutput> |
| </screen> |
| |
| </sect2> |
| |
| <sect2 id="functions-datetime-trunc"> |
| <title><function>date_trunc</function></title> |
| |
| <indexterm> |
| <primary>date_trunc</primary> |
| </indexterm> |
| |
| <para> |
| The function <function>date_trunc</function> is conceptually |
| similar to the <function>trunc</function> function for numbers. |
| </para> |
| |
| <para> |
| <synopsis> |
| date_trunc(<replaceable>field</replaceable>, <replaceable>source</replaceable> [, <replaceable>time_zone</replaceable> ]) |
| </synopsis> |
| <replaceable>source</replaceable> is a value expression of type |
| <type>timestamp</type>, <type>timestamp with time zone</type>, |
| or <type>interval</type>. |
| (Values of type <type>date</type> and |
| <type>time</type> are cast automatically to <type>timestamp</type> or |
| <type>interval</type>, respectively.) |
| <replaceable>field</replaceable> selects to which precision to |
| truncate the input value. The return value is likewise of type |
| <type>timestamp</type>, <type>timestamp with time zone</type>, |
| or <type>interval</type>, |
| and it has all fields that are less significant than the |
| selected one set to zero (or one, for day and month). |
| </para> |
| |
| <para> |
| Valid values for <replaceable>field</replaceable> are: |
| <simplelist> |
| <member><literal>microseconds</literal></member> |
| <member><literal>milliseconds</literal></member> |
| <member><literal>second</literal></member> |
| <member><literal>minute</literal></member> |
| <member><literal>hour</literal></member> |
| <member><literal>day</literal></member> |
| <member><literal>week</literal></member> |
| <member><literal>month</literal></member> |
| <member><literal>quarter</literal></member> |
| <member><literal>year</literal></member> |
| <member><literal>decade</literal></member> |
| <member><literal>century</literal></member> |
| <member><literal>millennium</literal></member> |
| </simplelist> |
| </para> |
| |
| <para> |
| When the input value is of type <type>timestamp with time zone</type>, |
| the truncation is performed with respect to a particular time zone; |
| for example, truncation to <literal>day</literal> produces a value that |
| is midnight in that zone. By default, truncation is done with respect |
| to the current <xref linkend="guc-timezone"/> setting, but the |
| optional <replaceable>time_zone</replaceable> argument can be provided |
| to specify a different time zone. The time zone name can be specified |
| in any of the ways described in <xref linkend="datatype-timezones"/>. |
| </para> |
| |
| <para> |
| A time zone cannot be specified when processing <type>timestamp without |
| time zone</type> or <type>interval</type> inputs. These are always |
| taken at face value. |
| </para> |
| |
| <para> |
| Examples (assuming the local time zone is <literal>America/New_York</literal>): |
| <screen> |
| SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40'); |
| <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 20:00:00</computeroutput> |
| |
| SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40'); |
| <lineannotation>Result: </lineannotation><computeroutput>2001-01-01 00:00:00</computeroutput> |
| |
| SELECT date_trunc('day', TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40+00'); |
| <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 00:00:00-05</computeroutput> |
| |
| SELECT date_trunc('day', TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40+00', 'Australia/Sydney'); |
| <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 08:00:00-05</computeroutput> |
| |
| SELECT date_trunc('hour', INTERVAL '3 days 02:47:33'); |
| <lineannotation>Result: </lineannotation><computeroutput>3 days 02:00:00</computeroutput> |
| </screen> |
| </para> |
| </sect2> |
| |
| <sect2 id="functions-datetime-bin"> |
| <title><function>date_bin</function></title> |
| |
| <indexterm> |
| <primary>date_bin</primary> |
| </indexterm> |
| |
| <para> |
| The function <function>date_bin</function> <quote>bins</quote> the input |
| timestamp into the specified interval (the <firstterm>stride</firstterm>) |
| aligned with a specified origin. |
| </para> |
| |
| <para> |
| <synopsis> |
| date_bin(<replaceable>stride</replaceable>, <replaceable>source</replaceable>, <replaceable>origin</replaceable>) |
| </synopsis> |
| <replaceable>source</replaceable> is a value expression of type |
| <type>timestamp</type> or <type>timestamp with time zone</type>. (Values |
| of type <type>date</type> are cast automatically to |
| <type>timestamp</type>.) <replaceable>stride</replaceable> is a value |
| expression of type <type>interval</type>. The return value is likewise |
| of type <type>timestamp</type> or <type>timestamp with time zone</type>, |
| and it marks the beginning of the bin into which the |
| <replaceable>source</replaceable> is placed. |
| </para> |
| |
| <para> |
| Examples: |
| <screen> |
| SELECT date_bin('15 minutes', TIMESTAMP '2020-02-11 15:44:17', TIMESTAMP '2001-01-01'); |
| <lineannotation>Result: </lineannotation><computeroutput>2020-02-11 15:30:00</computeroutput> |
| |
| SELECT date_bin('15 minutes', TIMESTAMP '2020-02-11 15:44:17', TIMESTAMP '2001-01-01 00:02:30'); |
| <lineannotation>Result: </lineannotation><computeroutput>2020-02-11 15:32:30</computeroutput> |
| </screen> |
| </para> |
| |
| <para> |
| In the case of full units (1 minute, 1 hour, etc.), it gives the same result as |
| the analogous <function>date_trunc</function> call, but the difference is |
| that <function>date_bin</function> can truncate to an arbitrary interval. |
| </para> |
| |
| <para> |
| The <parameter>stride</parameter> interval must be greater than zero and |
| cannot contain units of month or larger. |
| </para> |
| </sect2> |
| |
| <sect2 id="functions-datetime-zoneconvert"> |
| <title><literal>AT TIME ZONE</literal></title> |
| |
| <indexterm> |
| <primary>time zone</primary> |
| <secondary>conversion</secondary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>AT TIME ZONE</primary> |
| </indexterm> |
| |
| <para> |
| The <literal>AT TIME ZONE</literal> operator converts time |
| stamp <emphasis>without</emphasis> time zone to/from |
| time stamp <emphasis>with</emphasis> time zone, and |
| <type>time with time zone</type> values to different time |
| zones. <xref linkend="functions-datetime-zoneconvert-table"/> shows its |
| variants. |
| </para> |
| |
| <table id="functions-datetime-zoneconvert-table"> |
| <title><literal>AT TIME ZONE</literal> Variants</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Operator |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>timestamp without time zone</type> <literal>AT TIME ZONE</literal> <replaceable>zone</replaceable> |
| <returnvalue>timestamp with time zone</returnvalue> |
| </para> |
| <para> |
| Converts given time stamp <emphasis>without</emphasis> time zone to |
| time stamp <emphasis>with</emphasis> time zone, assuming the given |
| value is in the named time zone. |
| </para> |
| <para> |
| <literal>timestamp '2001-02-16 20:38:40' at time zone 'America/Denver'</literal> |
| <returnvalue>2001-02-17 03:38:40+00</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>timestamp with time zone</type> <literal>AT TIME ZONE</literal> <replaceable>zone</replaceable> |
| <returnvalue>timestamp without time zone</returnvalue> |
| </para> |
| <para> |
| Converts given time stamp <emphasis>with</emphasis> time zone to |
| time stamp <emphasis>without</emphasis> time zone, as the time would |
| appear in that zone. |
| </para> |
| <para> |
| <literal>timestamp with time zone '2001-02-16 20:38:40-05' at time zone 'America/Denver'</literal> |
| <returnvalue>2001-02-16 18:38:40</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>time with time zone</type> <literal>AT TIME ZONE</literal> <replaceable>zone</replaceable> |
| <returnvalue>time with time zone</returnvalue> |
| </para> |
| <para> |
| Converts given time <emphasis>with</emphasis> time zone to a new time |
| zone. Since no date is supplied, this uses the currently active UTC |
| offset for the named destination zone. |
| </para> |
| <para> |
| <literal>time with time zone '05:34:17-05' at time zone 'UTC'</literal> |
| <returnvalue>10:34:17+00</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| In these expressions, the desired time zone <replaceable>zone</replaceable> can be |
| specified either as a text value (e.g., <literal>'America/Los_Angeles'</literal>) |
| or as an interval (e.g., <literal>INTERVAL '-08:00'</literal>). |
| In the text case, a time zone name can be specified in any of the ways |
| described in <xref linkend="datatype-timezones"/>. |
| The interval case is only useful for zones that have fixed offsets from |
| UTC, so it is not very common in practice. |
| </para> |
| |
| <para> |
| Examples (assuming the current <xref linkend="guc-timezone"/> setting |
| is <literal>America/Los_Angeles</literal>): |
| <screen> |
| SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'America/Denver'; |
| <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 19:38:40-08</computeroutput> |
| |
| SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE 'America/Denver'; |
| <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 18:38:40</computeroutput> |
| |
| SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'Asia/Tokyo' AT TIME ZONE 'America/Chicago'; |
| <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 05:38:40</computeroutput> |
| </screen> |
| The first example adds a time zone to a value that lacks it, and |
| displays the value using the current <varname>TimeZone</varname> |
| setting. The second example shifts the time stamp with time zone value |
| to the specified time zone, and returns the value without a time zone. |
| This allows storage and display of values different from the current |
| <varname>TimeZone</varname> setting. The third example converts |
| Tokyo time to Chicago time. |
| </para> |
| |
| <para> |
| The function <literal><function>timezone</function>(<replaceable>zone</replaceable>, |
| <replaceable>timestamp</replaceable>)</literal> is equivalent to the SQL-conforming construct |
| <literal><replaceable>timestamp</replaceable> AT TIME ZONE |
| <replaceable>zone</replaceable></literal>. |
| </para> |
| </sect2> |
| |
| <sect2 id="functions-datetime-current"> |
| <title>Current Date/Time</title> |
| |
| <indexterm> |
| <primary>date</primary> |
| <secondary>current</secondary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>time</primary> |
| <secondary>current</secondary> |
| </indexterm> |
| |
| <para> |
| <productname>PostgreSQL</productname> provides a number of functions |
| that return values related to the current date and time. These |
| SQL-standard functions all return values based on the start time of |
| the current transaction: |
| <synopsis> |
| CURRENT_DATE |
| CURRENT_TIME |
| CURRENT_TIMESTAMP |
| CURRENT_TIME(<replaceable>precision</replaceable>) |
| CURRENT_TIMESTAMP(<replaceable>precision</replaceable>) |
| LOCALTIME |
| LOCALTIMESTAMP |
| LOCALTIME(<replaceable>precision</replaceable>) |
| LOCALTIMESTAMP(<replaceable>precision</replaceable>) |
| </synopsis> |
| </para> |
| |
| <para> |
| <function>CURRENT_TIME</function> and |
| <function>CURRENT_TIMESTAMP</function> deliver values with time zone; |
| <function>LOCALTIME</function> and |
| <function>LOCALTIMESTAMP</function> deliver values without time zone. |
| </para> |
| |
| <para> |
| <function>CURRENT_TIME</function>, |
| <function>CURRENT_TIMESTAMP</function>, |
| <function>LOCALTIME</function>, and |
| <function>LOCALTIMESTAMP</function> |
| can optionally take |
| a precision parameter, which causes the result to be rounded |
| to that many fractional digits in the seconds field. Without a precision parameter, |
| the result is given to the full available precision. |
| </para> |
| |
| <para> |
| Some examples: |
| <screen> |
| SELECT CURRENT_TIME; |
| <lineannotation>Result: </lineannotation><computeroutput>14:39:53.662522-05</computeroutput> |
| |
| SELECT CURRENT_DATE; |
| <lineannotation>Result: </lineannotation><computeroutput>2019-12-23</computeroutput> |
| |
| SELECT CURRENT_TIMESTAMP; |
| <lineannotation>Result: </lineannotation><computeroutput>2019-12-23 14:39:53.662522-05</computeroutput> |
| |
| SELECT CURRENT_TIMESTAMP(2); |
| <lineannotation>Result: </lineannotation><computeroutput>2019-12-23 14:39:53.66-05</computeroutput> |
| |
| SELECT LOCALTIMESTAMP; |
| <lineannotation>Result: </lineannotation><computeroutput>2019-12-23 14:39:53.662522</computeroutput> |
| </screen> |
| </para> |
| |
| <para> |
| Since these functions return |
| the start time of the current transaction, their values do not |
| change during the transaction. This is considered a feature: |
| the intent is to allow a single transaction to have a consistent |
| notion of the <quote>current</quote> time, so that multiple |
| modifications within the same transaction bear the same |
| time stamp. |
| </para> |
| |
| <note> |
| <para> |
| Other database systems might advance these values more |
| frequently. |
| </para> |
| </note> |
| |
| <para> |
| <productname>PostgreSQL</productname> also provides functions that |
| return the start time of the current statement, as well as the actual |
| current time at the instant the function is called. The complete list |
| of non-SQL-standard time functions is: |
| <synopsis> |
| transaction_timestamp() |
| statement_timestamp() |
| clock_timestamp() |
| timeofday() |
| now() |
| </synopsis> |
| </para> |
| |
| <para> |
| <function>transaction_timestamp()</function> is equivalent to |
| <function>CURRENT_TIMESTAMP</function>, but is named to clearly reflect |
| what it returns. |
| <function>statement_timestamp()</function> returns the start time of the current |
| statement (more specifically, the time of receipt of the latest command |
| message from the client). |
| <function>statement_timestamp()</function> and <function>transaction_timestamp()</function> |
| return the same value during the first command of a transaction, but might |
| differ during subsequent commands. |
| <function>clock_timestamp()</function> returns the actual current time, and |
| therefore its value changes even within a single SQL command. |
| <function>timeofday()</function> is a historical |
| <productname>PostgreSQL</productname> function. Like |
| <function>clock_timestamp()</function>, it returns the actual current time, |
| but as a formatted <type>text</type> string rather than a <type>timestamp |
| with time zone</type> value. |
| <function>now()</function> is a traditional <productname>PostgreSQL</productname> |
| equivalent to <function>transaction_timestamp()</function>. |
| </para> |
| |
| <para> |
| All the date/time data types also accept the special literal value |
| <literal>now</literal> to specify the current date and time (again, |
| interpreted as the transaction start time). Thus, |
| the following three all return the same result: |
| <programlisting> |
| SELECT CURRENT_TIMESTAMP; |
| SELECT now(); |
| SELECT TIMESTAMP 'now'; -- but see tip below |
| </programlisting> |
| </para> |
| |
| <tip> |
| <para> |
| Do not use the third form when specifying a value to be evaluated later, |
| for example in a <literal>DEFAULT</literal> clause for a table column. |
| The system will convert <literal>now</literal> |
| to a <type>timestamp</type> 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 |
| forms will not be evaluated until the default value is used, |
| because they are function calls. Thus they will give the desired |
| behavior of defaulting to the time of row insertion. |
| (See also <xref linkend="datatype-datetime-special-values"/>.) |
| </para> |
| </tip> |
| </sect2> |
| |
| <sect2 id="functions-datetime-delay"> |
| <title>Delaying Execution</title> |
| |
| <indexterm> |
| <primary>pg_sleep</primary> |
| </indexterm> |
| <indexterm> |
| <primary>pg_sleep_for</primary> |
| </indexterm> |
| <indexterm> |
| <primary>pg_sleep_until</primary> |
| </indexterm> |
| <indexterm> |
| <primary>sleep</primary> |
| </indexterm> |
| <indexterm> |
| <primary>delay</primary> |
| </indexterm> |
| |
| <para> |
| The following functions are available to delay execution of the server |
| process: |
| <synopsis> |
| pg_sleep ( <type>double precision</type> ) |
| pg_sleep_for ( <type>interval</type> ) |
| pg_sleep_until ( <type>timestamp with time zone</type> ) |
| </synopsis> |
| |
| <function>pg_sleep</function> makes the current session's process |
| sleep until the given number of seconds have |
| elapsed. Fractional-second delays can be specified. |
| <function>pg_sleep_for</function> is a convenience function to |
| allow the sleep time to be specified as an <type>interval</type>. |
| <function>pg_sleep_until</function> is a convenience function for when |
| a specific wake-up time is desired. |
| For example: |
| |
| <programlisting> |
| SELECT pg_sleep(1.5); |
| SELECT pg_sleep_for('5 minutes'); |
| SELECT pg_sleep_until('tomorrow 03:00'); |
| </programlisting> |
| </para> |
| |
| <note> |
| <para> |
| The effective resolution of the sleep interval is platform-specific; |
| 0.01 seconds is a common value. The sleep delay will be at least as long |
| as specified. It might be longer depending on factors such as server load. |
| In particular, <function>pg_sleep_until</function> is not guaranteed to |
| wake up exactly at the specified time, but it will not wake up any earlier. |
| </para> |
| </note> |
| |
| <warning> |
| <para> |
| Make sure that your session does not hold more locks than necessary |
| when calling <function>pg_sleep</function> or its variants. Otherwise |
| other sessions might have to wait for your sleeping process, slowing down |
| the entire system. |
| </para> |
| </warning> |
| </sect2> |
| |
| </sect1> |
| |
| |
| <sect1 id="functions-enum"> |
| <title>Enum Support Functions</title> |
| |
| <para> |
| For enum types (described in <xref linkend="datatype-enum"/>), |
| there are several functions that allow cleaner programming without |
| hard-coding particular values of an enum type. |
| These are listed in <xref linkend="functions-enum-table"/>. The examples |
| assume an enum type created as: |
| |
| <programlisting> |
| CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow', 'green', 'blue', 'purple'); |
| </programlisting> |
| |
| </para> |
| |
| <table id="functions-enum-table"> |
| <title>Enum Support Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>enum_first</primary> |
| </indexterm> |
| <function>enum_first</function> ( <type>anyenum</type> ) |
| <returnvalue>anyenum</returnvalue> |
| </para> |
| <para> |
| Returns the first value of the input enum type. |
| </para> |
| <para> |
| <literal>enum_first(null::rainbow)</literal> |
| <returnvalue>red</returnvalue> |
| </para></entry> |
| </row> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>enum_last</primary> |
| </indexterm> |
| <function>enum_last</function> ( <type>anyenum</type> ) |
| <returnvalue>anyenum</returnvalue> |
| </para> |
| <para> |
| Returns the last value of the input enum type. |
| </para> |
| <para> |
| <literal>enum_last(null::rainbow)</literal> |
| <returnvalue>purple</returnvalue> |
| </para></entry> |
| </row> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>enum_range</primary> |
| </indexterm> |
| <function>enum_range</function> ( <type>anyenum</type> ) |
| <returnvalue>anyarray</returnvalue> |
| </para> |
| <para> |
| Returns all values of the input enum type in an ordered array. |
| </para> |
| <para> |
| <literal>enum_range(null::rainbow)</literal> |
| <returnvalue>{red,orange,yellow,&zwsp;green,blue,purple}</returnvalue> |
| </para></entry> |
| </row> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>enum_range</function> ( <type>anyenum</type>, <type>anyenum</type> ) |
| <returnvalue>anyarray</returnvalue> |
| </para> |
| <para> |
| Returns the range between the two given enum values, as an ordered |
| array. The values must be from the same enum type. If the first |
| parameter is null, the result will start with the first value of |
| the enum type. |
| If the second parameter is null, the result will end with the last |
| value of the enum type. |
| </para> |
| <para> |
| <literal>enum_range('orange'::rainbow, 'green'::rainbow)</literal> |
| <returnvalue>{orange,yellow,green}</returnvalue> |
| </para> |
| <para> |
| <literal>enum_range(NULL, 'green'::rainbow)</literal> |
| <returnvalue>{red,orange,&zwsp;yellow,green}</returnvalue> |
| </para> |
| <para> |
| <literal>enum_range('orange'::rainbow, NULL)</literal> |
| <returnvalue>{orange,yellow,green,&zwsp;blue,purple}</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| Notice that except for the two-argument form of <function>enum_range</function>, |
| these functions disregard the specific value passed to them; they care |
| only about its declared data type. Either null or a specific value of |
| the type can be passed, with the same result. It is more common to |
| apply these functions to a table column or function argument than to |
| a hardwired type name as used in the examples. |
| </para> |
| </sect1> |
| |
| <sect1 id="functions-geometry"> |
| <title>Geometric Functions and Operators</title> |
| |
| <para> |
| The geometric types <type>point</type>, <type>box</type>, |
| <type>lseg</type>, <type>line</type>, <type>path</type>, |
| <type>polygon</type>, and <type>circle</type> have a large set of |
| native support functions and operators, shown in <xref |
| linkend="functions-geometry-op-table"/>, <xref |
| linkend="functions-geometry-func-table"/>, and <xref |
| linkend="functions-geometry-conv-table"/>. |
| </para> |
| |
| <table id="functions-geometry-op-table"> |
| <title>Geometric Operators</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Operator |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>geometric_type</replaceable> <literal>+</literal> <type>point</type> |
| <returnvalue><replaceable>geometric_type</replaceable></returnvalue> |
| </para> |
| <para> |
| Adds the coordinates of the second <type>point</type> to those of each |
| point of the first argument, thus performing translation. |
| Available for <type>point</type>, <type>box</type>, <type>path</type>, |
| <type>circle</type>. |
| </para> |
| <para> |
| <literal>box '(1,1),(0,0)' + point '(2,0)'</literal> |
| <returnvalue>(3,1),(2,0)</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>path</type> <literal>+</literal> <type>path</type> |
| <returnvalue>path</returnvalue> |
| </para> |
| <para> |
| Concatenates two open paths (returns NULL if either path is closed). |
| </para> |
| <para> |
| <literal>path '[(0,0),(1,1)]' + path '[(2,2),(3,3),(4,4)]'</literal> |
| <returnvalue>[(0,0),(1,1),(2,2),(3,3),(4,4)]</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>geometric_type</replaceable> <literal>-</literal> <type>point</type> |
| <returnvalue><replaceable>geometric_type</replaceable></returnvalue> |
| </para> |
| <para> |
| Subtracts the coordinates of the second <type>point</type> from those |
| of each point of the first argument, thus performing translation. |
| Available for <type>point</type>, <type>box</type>, <type>path</type>, |
| <type>circle</type>. |
| </para> |
| <para> |
| <literal>box '(1,1),(0,0)' - point '(2,0)'</literal> |
| <returnvalue>(-1,1),(-2,0)</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>geometric_type</replaceable> <literal>*</literal> <type>point</type> |
| <returnvalue><replaceable>geometric_type</replaceable></returnvalue> |
| </para> |
| <para> |
| Multiplies each point of the first argument by the second |
| <type>point</type> (treating a point as being a complex number |
| represented by real and imaginary parts, and performing standard |
| complex multiplication). If one interprets |
| the second <type>point</type> as a vector, this is equivalent to |
| scaling the object's size and distance from the origin by the length |
| of the vector, and rotating it counterclockwise around the origin by |
| the vector's angle from the <replaceable>x</replaceable> axis. |
| Available for <type>point</type>, <type>box</type>,<footnote |
| id="functions-geometry-rotation-fn"><para><quote>Rotating</quote> a |
| box with these operators only moves its corner points: the box is |
| still considered to have sides parallel to the axes. Hence the box's |
| size is not preserved, as a true rotation would do.</para></footnote> |
| <type>path</type>, <type>circle</type>. |
| </para> |
| <para> |
| <literal>path '((0,0),(1,0),(1,1))' * point '(3.0,0)'</literal> |
| <returnvalue>((0,0),(3,0),(3,3))</returnvalue> |
| </para> |
| <para> |
| <literal>path '((0,0),(1,0),(1,1))' * point(cosd(45), sind(45))</literal> |
| <returnvalue>((0,0),&zwsp;(0.7071067811865475,0.7071067811865475),&zwsp;(0,1.414213562373095))</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>geometric_type</replaceable> <literal>/</literal> <type>point</type> |
| <returnvalue><replaceable>geometric_type</replaceable></returnvalue> |
| </para> |
| <para> |
| Divides each point of the first argument by the second |
| <type>point</type> (treating a point as being a complex number |
| represented by real and imaginary parts, and performing standard |
| complex division). If one interprets |
| the second <type>point</type> as a vector, this is equivalent to |
| scaling the object's size and distance from the origin down by the |
| length of the vector, and rotating it clockwise around the origin by |
| the vector's angle from the <replaceable>x</replaceable> axis. |
| Available for <type>point</type>, <type>box</type>,<footnoteref |
| linkend="functions-geometry-rotation-fn"/> <type>path</type>, |
| <type>circle</type>. |
| </para> |
| <para> |
| <literal>path '((0,0),(1,0),(1,1))' / point '(2.0,0)'</literal> |
| <returnvalue>((0,0),(0.5,0),(0.5,0.5))</returnvalue> |
| </para> |
| <para> |
| <literal>path '((0,0),(1,0),(1,1))' / point(cosd(45), sind(45))</literal> |
| <returnvalue>((0,0),&zwsp;(0.7071067811865476,-0.7071067811865476),&zwsp;(1.4142135623730951,0))</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <literal>@-@</literal> <replaceable>geometric_type</replaceable> |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Computes the total length. |
| Available for <type>lseg</type>, <type>path</type>. |
| </para> |
| <para> |
| <literal>@-@ path '[(0,0),(1,0),(1,1)]'</literal> |
| <returnvalue>2</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <literal>@@</literal> <replaceable>geometric_type</replaceable> |
| <returnvalue>point</returnvalue> |
| </para> |
| <para> |
| Computes the center point. |
| Available for <type>box</type>, <type>lseg</type>, |
| <type>polygon</type>, <type>circle</type>. |
| </para> |
| <para> |
| <literal>@@ box '(2,2),(0,0)'</literal> |
| <returnvalue>(1,1)</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <literal>#</literal> <replaceable>geometric_type</replaceable> |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns the number of points. |
| Available for <type>path</type>, <type>polygon</type>. |
| </para> |
| <para> |
| <literal># path '((1,0),(0,1),(-1,0))'</literal> |
| <returnvalue>3</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>geometric_type</replaceable> <literal>#</literal> <replaceable>geometric_type</replaceable> |
| <returnvalue>point</returnvalue> |
| </para> |
| <para> |
| Computes the point of intersection, or NULL if there is none. |
| Available for <type>lseg</type>, <type>line</type>. |
| </para> |
| <para> |
| <literal>lseg '[(0,0),(1,1)]' # lseg '[(1,0),(0,1)]'</literal> |
| <returnvalue>(0.5,0.5)</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>box</type> <literal>#</literal> <type>box</type> |
| <returnvalue>box</returnvalue> |
| </para> |
| <para> |
| Computes the intersection of two boxes, or NULL if there is none. |
| </para> |
| <para> |
| <literal>box '(2,2),(-1,-1)' # box '(1,1),(-2,-2)'</literal> |
| <returnvalue>(1,1),(-1,-1)</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>geometric_type</replaceable> <literal>##</literal> <replaceable>geometric_type</replaceable> |
| <returnvalue>point</returnvalue> |
| </para> |
| <para> |
| Computes the closest point to the first object on the second object. |
| Available for these pairs of types: |
| (<type>point</type>, <type>box</type>), |
| (<type>point</type>, <type>lseg</type>), |
| (<type>point</type>, <type>line</type>), |
| (<type>lseg</type>, <type>box</type>), |
| (<type>lseg</type>, <type>lseg</type>), |
| (<type>line</type>, <type>lseg</type>). |
| </para> |
| <para> |
| <literal>point '(0,0)' ## lseg '[(2,0),(0,2)]'</literal> |
| <returnvalue>(1,1)</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>geometric_type</replaceable> <literal><-></literal> <replaceable>geometric_type</replaceable> |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Computes the distance between the objects. |
| Available for all geometric types except <type>polygon</type>, |
| for all combinations |
| of <type>point</type> with another geometric type, and for |
| these additional pairs of types: |
| (<type>box</type>, <type>lseg</type>), |
| (<type>lseg</type>, <type>line</type>), |
| (<type>polygon</type>, <type>circle</type>) |
| (and the commutator cases). |
| </para> |
| <para> |
| <literal>circle '<(0,0),1>' <-> circle '<(5,0),1>'</literal> |
| <returnvalue>3</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>geometric_type</replaceable> <literal>@></literal> <replaceable>geometric_type</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does first object contain second? |
| Available for these pairs of types: |
| (<literal>box</literal>, <literal>point</literal>), |
| (<literal>box</literal>, <literal>box</literal>), |
| (<literal>path</literal>, <literal>point</literal>), |
| (<literal>polygon</literal>, <literal>point</literal>), |
| (<literal>polygon</literal>, <literal>polygon</literal>), |
| (<literal>circle</literal>, <literal>point</literal>), |
| (<literal>circle</literal>, <literal>circle</literal>). |
| </para> |
| <para> |
| <literal>circle '<(0,0),2>' @> point '(1,1)'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>geometric_type</replaceable> <literal><@</literal> <replaceable>geometric_type</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is first object contained in or on second? |
| Available for these pairs of types: |
| (<literal>point</literal>, <literal>box</literal>), |
| (<literal>point</literal>, <literal>lseg</literal>), |
| (<literal>point</literal>, <literal>line</literal>), |
| (<literal>point</literal>, <literal>path</literal>), |
| (<literal>point</literal>, <literal>polygon</literal>), |
| (<literal>point</literal>, <literal>circle</literal>), |
| (<literal>box</literal>, <literal>box</literal>), |
| (<literal>lseg</literal>, <literal>box</literal>), |
| (<literal>lseg</literal>, <literal>line</literal>), |
| (<literal>polygon</literal>, <literal>polygon</literal>), |
| (<literal>circle</literal>, <literal>circle</literal>). |
| </para> |
| <para> |
| <literal>point '(1,1)' <@ circle '<(0,0),2>'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>geometric_type</replaceable> <literal>&&</literal> <replaceable>geometric_type</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Do these objects overlap? (One point in common makes this true.) |
| Available for <type>box</type>, <type>polygon</type>, |
| <type>circle</type>. |
| </para> |
| <para> |
| <literal>box '(1,1),(0,0)' && box '(2,2),(0,0)'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>geometric_type</replaceable> <literal><<</literal> <replaceable>geometric_type</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is first object strictly left of second? |
| Available for <type>point</type>, <type>box</type>, |
| <type>polygon</type>, <type>circle</type>. |
| </para> |
| <para> |
| <literal>circle '<(0,0),1>' << circle '<(5,0),1>'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>geometric_type</replaceable> <literal>>></literal> <replaceable>geometric_type</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is first object strictly right of second? |
| Available for <type>point</type>, <type>box</type>, |
| <type>polygon</type>, <type>circle</type>. |
| </para> |
| <para> |
| <literal>circle '<(5,0),1>' >> circle '<(0,0),1>'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>geometric_type</replaceable> <literal>&<</literal> <replaceable>geometric_type</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does first object not extend to the right of second? |
| Available for <type>box</type>, <type>polygon</type>, |
| <type>circle</type>. |
| </para> |
| <para> |
| <literal>box '(1,1),(0,0)' &< box '(2,2),(0,0)'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>geometric_type</replaceable> <literal>&></literal> <replaceable>geometric_type</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does first object not extend to the left of second? |
| Available for <type>box</type>, <type>polygon</type>, |
| <type>circle</type>. |
| </para> |
| <para> |
| <literal>box '(3,3),(0,0)' &> box '(2,2),(0,0)'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>geometric_type</replaceable> <literal><<|</literal> <replaceable>geometric_type</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is first object strictly below second? |
| Available for <type>point</type>, <type>box</type>, <type>polygon</type>, |
| <type>circle</type>. |
| </para> |
| <para> |
| <literal>box '(3,3),(0,0)' <<| box '(5,5),(3,4)'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>geometric_type</replaceable> <literal>|>></literal> <replaceable>geometric_type</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is first object strictly above second? |
| Available for <type>point</type>, <type>box</type>, <type>polygon</type>, |
| <type>circle</type>. |
| </para> |
| <para> |
| <literal>box '(5,5),(3,4)' |>> box '(3,3),(0,0)'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>geometric_type</replaceable> <literal>&<|</literal> <replaceable>geometric_type</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does first object not extend above second? |
| Available for <type>box</type>, <type>polygon</type>, |
| <type>circle</type>. |
| </para> |
| <para> |
| <literal>box '(1,1),(0,0)' &<| box '(2,2),(0,0)'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>geometric_type</replaceable> <literal>|&></literal> <replaceable>geometric_type</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does first object not extend below second? |
| Available for <type>box</type>, <type>polygon</type>, |
| <type>circle</type>. |
| </para> |
| <para> |
| <literal>box '(3,3),(0,0)' |&> box '(2,2),(0,0)'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>box</type> <literal><^</literal> <type>box</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is first object below second (allows edges to touch)? |
| </para> |
| <para> |
| <literal>box '((1,1),(0,0))' <^ box '((2,2),(1,1))'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>box</type> <literal>>^</literal> <type>box</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is first object above second (allows edges to touch)? |
| </para> |
| <para> |
| <literal>box '((2,2),(1,1))' >^ box '((1,1),(0,0))'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>geometric_type</replaceable> <literal>?#</literal> <replaceable>geometric_type</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Do these objects intersect? |
| Available for these pairs of types: |
| (<type>box</type>, <type>box</type>), |
| (<type>lseg</type>, <type>box</type>), |
| (<type>lseg</type>, <type>lseg</type>), |
| (<type>lseg</type>, <type>line</type>), |
| (<type>line</type>, <type>box</type>), |
| (<type>line</type>, <type>line</type>), |
| (<type>path</type>, <type>path</type>). |
| </para> |
| <para> |
| <literal>lseg '[(-1,0),(1,0)]' ?# box '(2,2),(-2,-2)'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <literal>?-</literal> <type>line</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <literal>?-</literal> <type>lseg</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is line horizontal? |
| </para> |
| <para> |
| <literal>?- lseg '[(-1,0),(1,0)]'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>point</type> <literal>?-</literal> <type>point</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Are points horizontally aligned (that is, have same y coordinate)? |
| </para> |
| <para> |
| <literal>point '(1,0)' ?- point '(0,0)'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <literal>?|</literal> <type>line</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <literal>?|</literal> <type>lseg</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is line vertical? |
| </para> |
| <para> |
| <literal>?| lseg '[(-1,0),(1,0)]'</literal> |
| <returnvalue>f</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>point</type> <literal>?|</literal> <type>point</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Are points vertically aligned (that is, have same x coordinate)? |
| </para> |
| <para> |
| <literal>point '(0,1)' ?| point '(0,0)'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>line</type> <literal>?-|</literal> <type>line</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <type>lseg</type> <literal>?-|</literal> <type>lseg</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Are lines perpendicular? |
| </para> |
| <para> |
| <literal>lseg '[(0,0),(0,1)]' ?-| lseg '[(0,0),(1,0)]'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>line</type> <literal>?||</literal> <type>line</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <type>lseg</type> <literal>?||</literal> <type>lseg</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Are lines parallel? |
| </para> |
| <para> |
| <literal>lseg '[(-1,0),(1,0)]' ?|| lseg '[(-1,2),(1,2)]'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>geometric_type</replaceable> <literal>~=</literal> <replaceable>geometric_type</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Are these objects the same? |
| Available for <type>point</type>, <type>box</type>, |
| <type>polygon</type>, <type>circle</type>. |
| </para> |
| <para> |
| <literal>polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <caution> |
| <para> |
| Note that the <quote>same as</quote> operator, <literal>~=</literal>, |
| represents the usual notion of equality for the <type>point</type>, |
| <type>box</type>, <type>polygon</type>, and <type>circle</type> types. |
| Some of the geometric types also have an <literal>=</literal> operator, but |
| <literal>=</literal> compares for equal <emphasis>areas</emphasis> only. |
| The other scalar comparison operators (<literal><=</literal> and so |
| on), where available for these types, likewise compare areas. |
| </para> |
| </caution> |
| |
| <note> |
| <para> |
| Before <productname>PostgreSQL</productname> 14, the point |
| is strictly below/above comparison operators <type>point</type> |
| <literal><<|</literal> <type>point</type> and <type>point</type> |
| <literal>|>></literal> <type>point</type> were respectively |
| called <literal><^</literal> and <literal>>^</literal>. These |
| names are still available, but are deprecated and will eventually be |
| removed. |
| </para> |
| </note> |
| |
| <table id="functions-geometry-func-table"> |
| <title>Geometric Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>area</primary> |
| </indexterm> |
| <function>area</function> ( <replaceable>geometric_type</replaceable> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Computes area. |
| Available for <type>box</type>, <type>path</type>, <type>circle</type>. |
| A <type>path</type> input must be closed, else NULL is returned. |
| Also, if the <type>path</type> is self-intersecting, the result may be |
| meaningless. |
| </para> |
| <para> |
| <literal>area(box '(2,2),(0,0)')</literal> |
| <returnvalue>4</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>center</primary> |
| </indexterm> |
| <function>center</function> ( <replaceable>geometric_type</replaceable> ) |
| <returnvalue>point</returnvalue> |
| </para> |
| <para> |
| Computes center point. |
| Available for <type>box</type>, <type>circle</type>. |
| </para> |
| <para> |
| <literal>center(box '(1,2),(0,0)')</literal> |
| <returnvalue>(0.5,1)</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>diagonal</primary> |
| </indexterm> |
| <function>diagonal</function> ( <type>box</type> ) |
| <returnvalue>lseg</returnvalue> |
| </para> |
| <para> |
| Extracts box's diagonal as a line segment |
| (same as <function>lseg(box)</function>). |
| </para> |
| <para> |
| <literal>diagonal(box '(1,2),(0,0)')</literal> |
| <returnvalue>[(1,2),(0,0)]</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>diameter</primary> |
| </indexterm> |
| <function>diameter</function> ( <type>circle</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Computes diameter of circle. |
| </para> |
| <para> |
| <literal>diameter(circle '<(0,0),2>')</literal> |
| <returnvalue>4</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>height</primary> |
| </indexterm> |
| <function>height</function> ( <type>box</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Computes vertical size of box. |
| </para> |
| <para> |
| <literal>height(box '(1,2),(0,0)')</literal> |
| <returnvalue>2</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>isclosed</primary> |
| </indexterm> |
| <function>isclosed</function> ( <type>path</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is path closed? |
| </para> |
| <para> |
| <literal>isclosed(path '((0,0),(1,1),(2,0))')</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>isopen</primary> |
| </indexterm> |
| <function>isopen</function> ( <type>path</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is path open? |
| </para> |
| <para> |
| <literal>isopen(path '[(0,0),(1,1),(2,0)]')</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>length</primary> |
| </indexterm> |
| <function>length</function> ( <replaceable>geometric_type</replaceable> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Computes the total length. |
| Available for <type>lseg</type>, <type>path</type>. |
| </para> |
| <para> |
| <literal>length(path '((-1,0),(1,0))')</literal> |
| <returnvalue>4</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>npoints</primary> |
| </indexterm> |
| <function>npoints</function> ( <replaceable>geometric_type</replaceable> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns the number of points. |
| Available for <type>path</type>, <type>polygon</type>. |
| </para> |
| <para> |
| <literal>npoints(path '[(0,0),(1,1),(2,0)]')</literal> |
| <returnvalue>3</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pclose</primary> |
| </indexterm> |
| <function>pclose</function> ( <type>path</type> ) |
| <returnvalue>path</returnvalue> |
| </para> |
| <para> |
| Converts path to closed form. |
| </para> |
| <para> |
| <literal>pclose(path '[(0,0),(1,1),(2,0)]')</literal> |
| <returnvalue>((0,0),(1,1),(2,0))</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>popen</primary> |
| </indexterm> |
| <function>popen</function> ( <type>path</type> ) |
| <returnvalue>path</returnvalue> |
| </para> |
| <para> |
| Converts path to open form. |
| </para> |
| <para> |
| <literal>popen(path '((0,0),(1,1),(2,0))')</literal> |
| <returnvalue>[(0,0),(1,1),(2,0)]</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>radius</primary> |
| </indexterm> |
| <function>radius</function> ( <type>circle</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Computes radius of circle. |
| </para> |
| <para> |
| <literal>radius(circle '<(0,0),2>')</literal> |
| <returnvalue>2</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>slope</primary> |
| </indexterm> |
| <function>slope</function> ( <type>point</type>, <type>point</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Computes slope of a line drawn through the two points. |
| </para> |
| <para> |
| <literal>slope(point '(0,0)', point '(2,1)')</literal> |
| <returnvalue>0.5</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>width</primary> |
| </indexterm> |
| <function>width</function> ( <type>box</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Computes horizontal size of box. |
| </para> |
| <para> |
| <literal>width(box '(1,2),(0,0)')</literal> |
| <returnvalue>1</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <table id="functions-geometry-conv-table"> |
| <title>Geometric Type Conversion Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| <tbody> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>box</primary> |
| </indexterm> |
| <function>box</function> ( <type>circle</type> ) |
| <returnvalue>box</returnvalue> |
| </para> |
| <para> |
| Computes box inscribed within the circle. |
| </para> |
| <para> |
| <literal>box(circle '<(0,0),2>')</literal> |
| <returnvalue>(1.414213562373095,1.414213562373095),&zwsp;(-1.414213562373095,-1.414213562373095)</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>box</function> ( <type>point</type> ) |
| <returnvalue>box</returnvalue> |
| </para> |
| <para> |
| Converts point to empty box. |
| </para> |
| <para> |
| <literal>box(point '(1,0)')</literal> |
| <returnvalue>(1,0),(1,0)</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>box</function> ( <type>point</type>, <type>point</type> ) |
| <returnvalue>box</returnvalue> |
| </para> |
| <para> |
| Converts any two corner points to box. |
| </para> |
| <para> |
| <literal>box(point '(0,1)', point '(1,0)')</literal> |
| <returnvalue>(1,1),(0,0)</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>box</function> ( <type>polygon</type> ) |
| <returnvalue>box</returnvalue> |
| </para> |
| <para> |
| Computes bounding box of polygon. |
| </para> |
| <para> |
| <literal>box(polygon '((0,0),(1,1),(2,0))')</literal> |
| <returnvalue>(2,1),(0,0)</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>bound_box</primary> |
| </indexterm> |
| <function>bound_box</function> ( <type>box</type>, <type>box</type> ) |
| <returnvalue>box</returnvalue> |
| </para> |
| <para> |
| Computes bounding box of two boxes. |
| </para> |
| <para> |
| <literal>bound_box(box '(1,1),(0,0)', box '(4,4),(3,3)')</literal> |
| <returnvalue>(4,4),(0,0)</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>circle</primary> |
| </indexterm> |
| <function>circle</function> ( <type>box</type> ) |
| <returnvalue>circle</returnvalue> |
| </para> |
| <para> |
| Computes smallest circle enclosing box. |
| </para> |
| <para> |
| <literal>circle(box '(1,1),(0,0)')</literal> |
| <returnvalue><(0.5,0.5),0.7071067811865476></returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>circle</function> ( <type>point</type>, <type>double precision</type> ) |
| <returnvalue>circle</returnvalue> |
| </para> |
| <para> |
| Constructs circle from center and radius. |
| </para> |
| <para> |
| <literal>circle(point '(0,0)', 2.0)</literal> |
| <returnvalue><(0,0),2></returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>circle</function> ( <type>polygon</type> ) |
| <returnvalue>circle</returnvalue> |
| </para> |
| <para> |
| Converts polygon to circle. The circle's center is the mean of the |
| positions of the polygon's points, and the radius is the average |
| distance of the polygon's points from that center. |
| </para> |
| <para> |
| <literal>circle(polygon '((0,0),(1,3),(2,0))')</literal> |
| <returnvalue><(1,1),1.6094757082487299></returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>line</primary> |
| </indexterm> |
| <function>line</function> ( <type>point</type>, <type>point</type> ) |
| <returnvalue>line</returnvalue> |
| </para> |
| <para> |
| Converts two points to the line through them. |
| </para> |
| <para> |
| <literal>line(point '(-1,0)', point '(1,0)')</literal> |
| <returnvalue>{0,-1,0}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>lseg</primary> |
| </indexterm> |
| <function>lseg</function> ( <type>box</type> ) |
| <returnvalue>lseg</returnvalue> |
| </para> |
| <para> |
| Extracts box's diagonal as a line segment. |
| </para> |
| <para> |
| <literal>lseg(box '(1,0),(-1,0)')</literal> |
| <returnvalue>[(1,0),(-1,0)]</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>lseg</function> ( <type>point</type>, <type>point</type> ) |
| <returnvalue>lseg</returnvalue> |
| </para> |
| <para> |
| Constructs line segment from two endpoints. |
| </para> |
| <para> |
| <literal>lseg(point '(-1,0)', point '(1,0)')</literal> |
| <returnvalue>[(-1,0),(1,0)]</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>path</primary> |
| </indexterm> |
| <function>path</function> ( <type>polygon</type> ) |
| <returnvalue>path</returnvalue> |
| </para> |
| <para> |
| Converts polygon to a closed path with the same list of points. |
| </para> |
| <para> |
| <literal>path(polygon '((0,0),(1,1),(2,0))')</literal> |
| <returnvalue>((0,0),(1,1),(2,0))</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>point</primary> |
| </indexterm> |
| <function>point</function> ( <type>double precision</type>, <type>double precision</type> ) |
| <returnvalue>point</returnvalue> |
| </para> |
| <para> |
| Constructs point from its coordinates. |
| </para> |
| <para> |
| <literal>point(23.4, -44.5)</literal> |
| <returnvalue>(23.4,-44.5)</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>point</function> ( <type>box</type> ) |
| <returnvalue>point</returnvalue> |
| </para> |
| <para> |
| Computes center of box. |
| </para> |
| <para> |
| <literal>point(box '(1,0),(-1,0)')</literal> |
| <returnvalue>(0,0)</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>point</function> ( <type>circle</type> ) |
| <returnvalue>point</returnvalue> |
| </para> |
| <para> |
| Computes center of circle. |
| </para> |
| <para> |
| <literal>point(circle '<(0,0),2>')</literal> |
| <returnvalue>(0,0)</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>point</function> ( <type>lseg</type> ) |
| <returnvalue>point</returnvalue> |
| </para> |
| <para> |
| Computes center of line segment. |
| </para> |
| <para> |
| <literal>point(lseg '[(-1,0),(1,0)]')</literal> |
| <returnvalue>(0,0)</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>point</function> ( <type>polygon</type> ) |
| <returnvalue>point</returnvalue> |
| </para> |
| <para> |
| Computes center of polygon (the mean of the |
| positions of the polygon's points). |
| </para> |
| <para> |
| <literal>point(polygon '((0,0),(1,1),(2,0))')</literal> |
| <returnvalue>(1,0.3333333333333333)</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>polygon</primary> |
| </indexterm> |
| <function>polygon</function> ( <type>box</type> ) |
| <returnvalue>polygon</returnvalue> |
| </para> |
| <para> |
| Converts box to a 4-point polygon. |
| </para> |
| <para> |
| <literal>polygon(box '(1,1),(0,0)')</literal> |
| <returnvalue>((0,0),(0,1),(1,1),(1,0))</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>polygon</function> ( <type>circle</type> ) |
| <returnvalue>polygon</returnvalue> |
| </para> |
| <para> |
| Converts circle to a 12-point polygon. |
| </para> |
| <para> |
| <literal>polygon(circle '<(0,0),2>')</literal> |
| <returnvalue>((-2,0),&zwsp;(-1.7320508075688774,0.9999999999999999),&zwsp;(-1.0000000000000002,1.7320508075688772),&zwsp;(-1.2246063538223773e-16,2),&zwsp;(0.9999999999999996,1.7320508075688774),&zwsp;(1.732050807568877,1.0000000000000007),&zwsp;(2,2.4492127076447545e-16),&zwsp;(1.7320508075688776,-0.9999999999999994),&zwsp;(1.0000000000000009,-1.7320508075688767),&zwsp;(3.673819061467132e-16,-2),&zwsp;(-0.9999999999999987,-1.732050807568878),&zwsp;(-1.7320508075688767,-1.0000000000000009))</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>polygon</function> ( <type>integer</type>, <type>circle</type> ) |
| <returnvalue>polygon</returnvalue> |
| </para> |
| <para> |
| Converts circle to an <replaceable>n</replaceable>-point polygon. |
| </para> |
| <para> |
| <literal>polygon(4, circle '<(3,0),1>')</literal> |
| <returnvalue>((2,0),&zwsp;(3,1),&zwsp;(4,1.2246063538223773e-16),&zwsp;(3,-1))</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>polygon</function> ( <type>path</type> ) |
| <returnvalue>polygon</returnvalue> |
| </para> |
| <para> |
| Converts closed path to a polygon with the same list of points. |
| </para> |
| <para> |
| <literal>polygon(path '((0,0),(1,1),(2,0))')</literal> |
| <returnvalue>((0,0),(1,1),(2,0))</returnvalue> |
| </para></entry> |
| </row> |
| |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| It is possible to access the two component numbers of a <type>point</type> |
| as though the point were an array with indexes 0 and 1. For example, if |
| <literal>t.p</literal> is a <type>point</type> column then |
| <literal>SELECT p[0] FROM t</literal> retrieves the X coordinate and |
| <literal>UPDATE t SET p[1] = ...</literal> changes the Y coordinate. |
| In the same way, a value of type <type>box</type> or <type>lseg</type> can be treated |
| as an array of two <type>point</type> values. |
| </para> |
| |
| </sect1> |
| |
| |
| <sect1 id="functions-net"> |
| <title>Network Address Functions and Operators</title> |
| |
| <para> |
| The IP network address types, <type>cidr</type> and <type>inet</type>, |
| support the usual comparison operators shown in |
| <xref linkend="functions-comparison-op-table"/> |
| as well as the specialized operators and functions shown in |
| <xref linkend="cidr-inet-operators-table"/> and |
| <xref linkend="cidr-inet-functions-table"/>. |
| </para> |
| |
| <para> |
| Any <type>cidr</type> value can be cast to <type>inet</type> implicitly; |
| therefore, the operators and functions shown below as operating on |
| <type>inet</type> also work on <type>cidr</type> values. (Where there are |
| separate functions for <type>inet</type> and <type>cidr</type>, it is |
| because the behavior should be different for the two cases.) |
| Also, it is permitted to cast an <type>inet</type> value |
| to <type>cidr</type>. When this is done, any bits to the right of the |
| netmask are silently zeroed to create a valid <type>cidr</type> value. |
| </para> |
| |
| <table id="cidr-inet-operators-table"> |
| <title>IP Address Operators</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Operator |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>inet</type> <literal><<</literal> <type>inet</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is subnet strictly contained by subnet? |
| This operator, and the next four, test for subnet inclusion. They |
| consider only the network parts of the two addresses (ignoring any |
| bits to the right of the netmasks) and determine whether one network |
| is identical to or a subnet of the other. |
| </para> |
| <para> |
| <literal>inet '192.168.1.5' << inet '192.168.1/24'</literal> |
| <returnvalue>t</returnvalue> |
| </para> |
| <para> |
| <literal>inet '192.168.0.5' << inet '192.168.1/24'</literal> |
| <returnvalue>f</returnvalue> |
| </para> |
| <para> |
| <literal>inet '192.168.1/24' << inet '192.168.1/24'</literal> |
| <returnvalue>f</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>inet</type> <literal><<=</literal> <type>inet</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is subnet contained by or equal to subnet? |
| </para> |
| <para> |
| <literal>inet '192.168.1/24' <<= inet '192.168.1/24'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>inet</type> <literal>>></literal> <type>inet</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does subnet strictly contain subnet? |
| </para> |
| <para> |
| <literal>inet '192.168.1/24' >> inet '192.168.1.5'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>inet</type> <literal>>>=</literal> <type>inet</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does subnet contain or equal subnet? |
| </para> |
| <para> |
| <literal>inet '192.168.1/24' >>= inet '192.168.1/24'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>inet</type> <literal>&&</literal> <type>inet</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does either subnet contain or equal the other? |
| </para> |
| <para> |
| <literal>inet '192.168.1/24' && inet '192.168.1.80/28'</literal> |
| <returnvalue>t</returnvalue> |
| </para> |
| <para> |
| <literal>inet '192.168.1/24' && inet '192.168.2.0/28'</literal> |
| <returnvalue>f</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <literal>~</literal> <type>inet</type> |
| <returnvalue>inet</returnvalue> |
| </para> |
| <para> |
| Computes bitwise NOT. |
| </para> |
| <para> |
| <literal>~ inet '192.168.1.6'</literal> |
| <returnvalue>63.87.254.249</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>inet</type> <literal>&</literal> <type>inet</type> |
| <returnvalue>inet</returnvalue> |
| </para> |
| <para> |
| Computes bitwise AND. |
| </para> |
| <para> |
| <literal>inet '192.168.1.6' & inet '0.0.0.255'</literal> |
| <returnvalue>0.0.0.6</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>inet</type> <literal>|</literal> <type>inet</type> |
| <returnvalue>inet</returnvalue> |
| </para> |
| <para> |
| Computes bitwise OR. |
| </para> |
| <para> |
| <literal>inet '192.168.1.6' | inet '0.0.0.255'</literal> |
| <returnvalue>192.168.1.255</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>inet</type> <literal>+</literal> <type>bigint</type> |
| <returnvalue>inet</returnvalue> |
| </para> |
| <para> |
| Adds an offset to an address. |
| </para> |
| <para> |
| <literal>inet '192.168.1.6' + 25</literal> |
| <returnvalue>192.168.1.31</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>bigint</type> <literal>+</literal> <type>inet</type> |
| <returnvalue>inet</returnvalue> |
| </para> |
| <para> |
| Adds an offset to an address. |
| </para> |
| <para> |
| <literal>200 + inet '::ffff:fff0:1'</literal> |
| <returnvalue>::ffff:255.240.0.201</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>inet</type> <literal>-</literal> <type>bigint</type> |
| <returnvalue>inet</returnvalue> |
| </para> |
| <para> |
| Subtracts an offset from an address. |
| </para> |
| <para> |
| <literal>inet '192.168.1.43' - 36</literal> |
| <returnvalue>192.168.1.7</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>inet</type> <literal>-</literal> <type>inet</type> |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para> |
| Computes the difference of two addresses. |
| </para> |
| <para> |
| <literal>inet '192.168.1.43' - inet '192.168.1.19'</literal> |
| <returnvalue>24</returnvalue> |
| </para> |
| <para> |
| <literal>inet '::1' - inet '::ffff:1'</literal> |
| <returnvalue>-4294901760</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <table id="cidr-inet-functions-table"> |
| <title>IP Address Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>abbrev</primary> |
| </indexterm> |
| <function>abbrev</function> ( <type>inet</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Creates an abbreviated display format as text. |
| (The result is the same as the <type>inet</type> output function |
| produces; it is <quote>abbreviated</quote> only in comparison to the |
| result of an explicit cast to <type>text</type>, which for historical |
| reasons will never suppress the netmask part.) |
| </para> |
| <para> |
| <literal>abbrev(inet '10.1.0.0/32')</literal> |
| <returnvalue>10.1.0.0</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>abbrev</function> ( <type>cidr</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Creates an abbreviated display format as text. |
| (The abbreviation consists of dropping all-zero octets to the right |
| of the netmask; more examples are in |
| <xref linkend="datatype-net-cidr-table"/>.) |
| </para> |
| <para> |
| <literal>abbrev(cidr '10.1.0.0/16')</literal> |
| <returnvalue>10.1/16</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>broadcast</primary> |
| </indexterm> |
| <function>broadcast</function> ( <type>inet</type> ) |
| <returnvalue>inet</returnvalue> |
| </para> |
| <para> |
| Computes the broadcast address for the address's network. |
| </para> |
| <para> |
| <literal>broadcast(inet '192.168.1.5/24')</literal> |
| <returnvalue>192.168.1.255/24</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>family</primary> |
| </indexterm> |
| <function>family</function> ( <type>inet</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns the address's family: <literal>4</literal> for IPv4, |
| <literal>6</literal> for IPv6. |
| </para> |
| <para> |
| <literal>family(inet '::1')</literal> |
| <returnvalue>6</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>host</primary> |
| </indexterm> |
| <function>host</function> ( <type>inet</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Returns the IP address as text, ignoring the netmask. |
| </para> |
| <para> |
| <literal>host(inet '192.168.1.0/24')</literal> |
| <returnvalue>192.168.1.0</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>hostmask</primary> |
| </indexterm> |
| <function>hostmask</function> ( <type>inet</type> ) |
| <returnvalue>inet</returnvalue> |
| </para> |
| <para> |
| Computes the host mask for the address's network. |
| </para> |
| <para> |
| <literal>hostmask(inet '192.168.23.20/30')</literal> |
| <returnvalue>0.0.0.3</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>inet_merge</primary> |
| </indexterm> |
| <function>inet_merge</function> ( <type>inet</type>, <type>inet</type> ) |
| <returnvalue>cidr</returnvalue> |
| </para> |
| <para> |
| Computes the smallest network that includes both of the given networks. |
| </para> |
| <para> |
| <literal>inet_merge(inet '192.168.1.5/24', inet '192.168.2.5/24')</literal> |
| <returnvalue>192.168.0.0/22</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>inet_same_family</primary> |
| </indexterm> |
| <function>inet_same_family</function> ( <type>inet</type>, <type>inet</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Tests whether the addresses belong to the same IP family. |
| </para> |
| <para> |
| <literal>inet_same_family(inet '192.168.1.5/24', inet '::1')</literal> |
| <returnvalue>f</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>masklen</primary> |
| </indexterm> |
| <function>masklen</function> ( <type>inet</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns the netmask length in bits. |
| </para> |
| <para> |
| <literal>masklen(inet '192.168.1.5/24')</literal> |
| <returnvalue>24</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>netmask</primary> |
| </indexterm> |
| <function>netmask</function> ( <type>inet</type> ) |
| <returnvalue>inet</returnvalue> |
| </para> |
| <para> |
| Computes the network mask for the address's network. |
| </para> |
| <para> |
| <literal>netmask(inet '192.168.1.5/24')</literal> |
| <returnvalue>255.255.255.0</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>network</primary> |
| </indexterm> |
| <function>network</function> ( <type>inet</type> ) |
| <returnvalue>cidr</returnvalue> |
| </para> |
| <para> |
| Returns the network part of the address, zeroing out |
| whatever is to the right of the netmask. |
| (This is equivalent to casting the value to <type>cidr</type>.) |
| </para> |
| <para> |
| <literal>network(inet '192.168.1.5/24')</literal> |
| <returnvalue>192.168.1.0/24</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>set_masklen</primary> |
| </indexterm> |
| <function>set_masklen</function> ( <type>inet</type>, <type>integer</type> ) |
| <returnvalue>inet</returnvalue> |
| </para> |
| <para> |
| Sets the netmask length for an <type>inet</type> value. |
| The address part does not change. |
| </para> |
| <para> |
| <literal>set_masklen(inet '192.168.1.5/24', 16)</literal> |
| <returnvalue>192.168.1.5/16</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>set_masklen</function> ( <type>cidr</type>, <type>integer</type> ) |
| <returnvalue>cidr</returnvalue> |
| </para> |
| <para> |
| Sets the netmask length for a <type>cidr</type> value. |
| Address bits to the right of the new netmask are set to zero. |
| </para> |
| <para> |
| <literal>set_masklen(cidr '192.168.1.0/24', 16)</literal> |
| <returnvalue>192.168.0.0/16</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>text</primary> |
| </indexterm> |
| <function>text</function> ( <type>inet</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Returns the unabbreviated IP address and netmask length as text. |
| (This has the same result as an explicit cast to <type>text</type>.) |
| </para> |
| <para> |
| <literal>text(inet '192.168.1.5')</literal> |
| <returnvalue>192.168.1.5/32</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <tip> |
| <para> |
| The <function>abbrev</function>, <function>host</function>, |
| and <function>text</function> functions are primarily intended to offer |
| alternative display formats for IP addresses. |
| </para> |
| </tip> |
| |
| <para> |
| The MAC address types, <type>macaddr</type> and <type>macaddr8</type>, |
| support the usual comparison operators shown in |
| <xref linkend="functions-comparison-op-table"/> |
| as well as the specialized functions shown in |
| <xref linkend="macaddr-functions-table"/>. |
| In addition, they support the bitwise logical operators |
| <literal>~</literal>, <literal>&</literal> and <literal>|</literal> |
| (NOT, AND and OR), just as shown above for IP addresses. |
| </para> |
| |
| <table id="macaddr-functions-table"> |
| <title>MAC Address Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>trunc</primary> |
| </indexterm> |
| <function>trunc</function> ( <type>macaddr</type> ) |
| <returnvalue>macaddr</returnvalue> |
| </para> |
| <para> |
| Sets the last 3 bytes of the address to zero. The remaining prefix |
| can be associated with a particular manufacturer (using data not |
| included in <productname>PostgreSQL</productname>). |
| </para> |
| <para> |
| <literal>trunc(macaddr '12:34:56:78:90:ab')</literal> |
| <returnvalue>12:34:56:00:00:00</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>trunc</function> ( <type>macaddr8</type> ) |
| <returnvalue>macaddr8</returnvalue> |
| </para> |
| <para> |
| Sets the last 5 bytes of the address to zero. The remaining prefix |
| can be associated with a particular manufacturer (using data not |
| included in <productname>PostgreSQL</productname>). |
| </para> |
| <para> |
| <literal>trunc(macaddr8 '12:34:56:78:90:ab:cd:ef')</literal> |
| <returnvalue>12:34:56:00:00:00:00:00</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>macaddr8_set7bit</primary> |
| </indexterm> |
| <function>macaddr8_set7bit</function> ( <type>macaddr8</type> ) |
| <returnvalue>macaddr8</returnvalue> |
| </para> |
| <para> |
| Sets the 7th bit of the address to one, creating what is known as |
| modified EUI-64, for inclusion in an IPv6 address. |
| </para> |
| <para> |
| <literal>macaddr8_set7bit(macaddr8 '00:34:56:ab:cd:ef')</literal> |
| <returnvalue>02:34:56:ff:fe:ab:cd:ef</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| </sect1> |
| |
| |
| <sect1 id="functions-textsearch"> |
| <title>Text Search Functions and Operators</title> |
| |
| <indexterm zone="datatype-textsearch"> |
| <primary>full text search</primary> |
| <secondary>functions and operators</secondary> |
| </indexterm> |
| |
| <indexterm zone="datatype-textsearch"> |
| <primary>text search</primary> |
| <secondary>functions and operators</secondary> |
| </indexterm> |
| |
| <para> |
| <xref linkend="textsearch-operators-table"/>, |
| <xref linkend="textsearch-functions-table"/> and |
| <xref linkend="textsearch-functions-debug-table"/> |
| summarize the functions and operators that are provided |
| for full text searching. See <xref linkend="textsearch"/> for a detailed |
| explanation of <productname>PostgreSQL</productname>'s text search |
| facility. |
| </para> |
| |
| <table id="textsearch-operators-table"> |
| <title>Text Search Operators</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Operator |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>tsvector</type> <literal>@@</literal> <type>tsquery</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <type>tsquery</type> <literal>@@</literal> <type>tsvector</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does <type>tsvector</type> match <type>tsquery</type>? |
| (The arguments can be given in either order.) |
| </para> |
| <para> |
| <literal>to_tsvector('fat cats ate rats') @@ to_tsquery('cat & rat')</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>text</type> <literal>@@</literal> <type>tsquery</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does text string, after implicit invocation |
| of <function>to_tsvector()</function>, match <type>tsquery</type>? |
| </para> |
| <para> |
| <literal>'fat cats ate rats' @@ to_tsquery('cat & rat')</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>tsvector</type> <literal>@@@</literal> <type>tsquery</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <type>tsquery</type> <literal>@@@</literal> <type>tsvector</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| This is a deprecated synonym for <literal>@@</literal>. |
| </para> |
| <para> |
| <literal>to_tsvector('fat cats ate rats') @@@ to_tsquery('cat & rat')</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>tsvector</type> <literal>||</literal> <type>tsvector</type> |
| <returnvalue>tsvector</returnvalue> |
| </para> |
| <para> |
| Concatenates two <type>tsvector</type>s. If both inputs contain |
| lexeme positions, the second input's positions are adjusted |
| accordingly. |
| </para> |
| <para> |
| <literal>'a:1 b:2'::tsvector || 'c:1 d:2 b:3'::tsvector</literal> |
| <returnvalue>'a':1 'b':2,5 'c':3 'd':4</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>tsquery</type> <literal>&&</literal> <type>tsquery</type> |
| <returnvalue>tsquery</returnvalue> |
| </para> |
| <para> |
| ANDs two <type>tsquery</type>s together, producing a query that |
| matches documents that match both input queries. |
| </para> |
| <para> |
| <literal>'fat | rat'::tsquery && 'cat'::tsquery</literal> |
| <returnvalue>( 'fat' | 'rat' ) & 'cat'</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>tsquery</type> <literal>||</literal> <type>tsquery</type> |
| <returnvalue>tsquery</returnvalue> |
| </para> |
| <para> |
| ORs two <type>tsquery</type>s together, producing a query that |
| matches documents that match either input query. |
| </para> |
| <para> |
| <literal>'fat | rat'::tsquery || 'cat'::tsquery</literal> |
| <returnvalue>'fat' | 'rat' | 'cat'</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <literal>!!</literal> <type>tsquery</type> |
| <returnvalue>tsquery</returnvalue> |
| </para> |
| <para> |
| Negates a <type>tsquery</type>, producing a query that matches |
| documents that do not match the input query. |
| </para> |
| <para> |
| <literal>!! 'cat'::tsquery</literal> |
| <returnvalue>!'cat'</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>tsquery</type> <literal><-></literal> <type>tsquery</type> |
| <returnvalue>tsquery</returnvalue> |
| </para> |
| <para> |
| Constructs a phrase query, which matches if the two input queries |
| match at successive lexemes. |
| </para> |
| <para> |
| <literal>to_tsquery('fat') <-> to_tsquery('rat')</literal> |
| <returnvalue>'fat' <-> 'rat'</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>tsquery</type> <literal>@></literal> <type>tsquery</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does first <type>tsquery</type> contain the second? (This considers |
| only whether all the lexemes appearing in one query appear in the |
| other, ignoring the combining operators.) |
| </para> |
| <para> |
| <literal>'cat'::tsquery @> 'cat & rat'::tsquery</literal> |
| <returnvalue>f</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>tsquery</type> <literal><@</literal> <type>tsquery</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is first <type>tsquery</type> contained in the second? (This |
| considers only whether all the lexemes appearing in one query appear |
| in the other, ignoring the combining operators.) |
| </para> |
| <para> |
| <literal>'cat'::tsquery <@ 'cat & rat'::tsquery</literal> |
| <returnvalue>t</returnvalue> |
| </para> |
| <para> |
| <literal>'cat'::tsquery <@ '!cat & rat'::tsquery</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| In addition to these specialized operators, the usual comparison |
| operators shown in <xref linkend="functions-comparison-op-table"/> are |
| available for types <type>tsvector</type> and <type>tsquery</type>. |
| These are not very |
| useful for text searching but allow, for example, unique indexes to be |
| built on columns of these types. |
| </para> |
| |
| <table id="textsearch-functions-table"> |
| <title>Text Search Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>array_to_tsvector</primary> |
| </indexterm> |
| <function>array_to_tsvector</function> ( <type>text[]</type> ) |
| <returnvalue>tsvector</returnvalue> |
| </para> |
| <para> |
| Converts an array of lexemes to a <type>tsvector</type>. |
| The given strings are used as-is without further processing. |
| </para> |
| <para> |
| <literal>array_to_tsvector('{fat,cat,rat}'::text[])</literal> |
| <returnvalue>'cat' 'fat' 'rat'</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>get_current_ts_config</primary> |
| </indexterm> |
| <function>get_current_ts_config</function> ( ) |
| <returnvalue>regconfig</returnvalue> |
| </para> |
| <para> |
| Returns the OID of the current default text search configuration |
| (as set by <xref linkend="guc-default-text-search-config"/>). |
| </para> |
| <para> |
| <literal>get_current_ts_config()</literal> |
| <returnvalue>english</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>length</primary> |
| </indexterm> |
| <function>length</function> ( <type>tsvector</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns the number of lexemes in the <type>tsvector</type>. |
| </para> |
| <para> |
| <literal>length('fat:2,4 cat:3 rat:5A'::tsvector)</literal> |
| <returnvalue>3</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>numnode</primary> |
| </indexterm> |
| <function>numnode</function> ( <type>tsquery</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns the number of lexemes plus operators in |
| the <type>tsquery</type>. |
| </para> |
| <para> |
| <literal>numnode('(fat & rat) | cat'::tsquery)</literal> |
| <returnvalue>5</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>plainto_tsquery</primary> |
| </indexterm> |
| <function>plainto_tsquery</function> ( |
| <optional> <parameter>config</parameter> <type>regconfig</type>, </optional> |
| <parameter>query</parameter> <type>text</type> ) |
| <returnvalue>tsquery</returnvalue> |
| </para> |
| <para> |
| Converts text to a <type>tsquery</type>, normalizing words according to |
| the specified or default configuration. Any punctuation in the string |
| is ignored (it does not determine query operators). The resulting |
| query matches documents containing all non-stopwords in the text. |
| </para> |
| <para> |
| <literal>plainto_tsquery('english', 'The Fat Rats')</literal> |
| <returnvalue>'fat' & 'rat'</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>phraseto_tsquery</primary> |
| </indexterm> |
| <function>phraseto_tsquery</function> ( |
| <optional> <parameter>config</parameter> <type>regconfig</type>, </optional> |
| <parameter>query</parameter> <type>text</type> ) |
| <returnvalue>tsquery</returnvalue> |
| </para> |
| <para> |
| Converts text to a <type>tsquery</type>, normalizing words according to |
| the specified or default configuration. Any punctuation in the string |
| is ignored (it does not determine query operators). The resulting |
| query matches phrases containing all non-stopwords in the text. |
| </para> |
| <para> |
| <literal>phraseto_tsquery('english', 'The Fat Rats')</literal> |
| <returnvalue>'fat' <-> 'rat'</returnvalue> |
| </para> |
| <para> |
| <literal>phraseto_tsquery('english', 'The Cat and Rats')</literal> |
| <returnvalue>'cat' <2> 'rat'</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>websearch_to_tsquery</primary> |
| </indexterm> |
| <function>websearch_to_tsquery</function> ( |
| <optional> <parameter>config</parameter> <type>regconfig</type>, </optional> |
| <parameter>query</parameter> <type>text</type> ) |
| <returnvalue>tsquery</returnvalue> |
| </para> |
| <para> |
| Converts text to a <type>tsquery</type>, normalizing words according |
| to the specified or default configuration. Quoted word sequences are |
| converted to phrase tests. The word <quote>or</quote> is understood |
| as producing an OR operator, and a dash produces a NOT operator; |
| other punctuation is ignored. |
| This approximates the behavior of some common web search tools. |
| </para> |
| <para> |
| <literal>websearch_to_tsquery('english', '"fat rat" or cat dog')</literal> |
| <returnvalue>'fat' <-> 'rat' | 'cat' & 'dog'</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>querytree</primary> |
| </indexterm> |
| <function>querytree</function> ( <type>tsquery</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Produces a representation of the indexable portion of |
| a <type>tsquery</type>. A result that is empty or |
| just <literal>T</literal> indicates a non-indexable query. |
| </para> |
| <para> |
| <literal>querytree('foo & ! bar'::tsquery)</literal> |
| <returnvalue>'foo'</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>setweight</primary> |
| </indexterm> |
| <function>setweight</function> ( <parameter>vector</parameter> <type>tsvector</type>, <parameter>weight</parameter> <type>"char"</type> ) |
| <returnvalue>tsvector</returnvalue> |
| </para> |
| <para> |
| Assigns the specified <parameter>weight</parameter> to each element |
| of the <parameter>vector</parameter>. |
| </para> |
| <para> |
| <literal>setweight('fat:2,4 cat:3 rat:5B'::tsvector, 'A')</literal> |
| <returnvalue>'cat':3A 'fat':2A,4A 'rat':5A</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>setweight</primary> |
| <secondary>setweight for specific lexeme(s)</secondary> |
| </indexterm> |
| <function>setweight</function> ( <parameter>vector</parameter> <type>tsvector</type>, <parameter>weight</parameter> <type>"char"</type>, <parameter>lexemes</parameter> <type>text[]</type> ) |
| <returnvalue>tsvector</returnvalue> |
| </para> |
| <para> |
| Assigns the specified <parameter>weight</parameter> to elements |
| of the <parameter>vector</parameter> that are listed |
| in <parameter>lexemes</parameter>. |
| </para> |
| <para> |
| <literal>setweight('fat:2,4 cat:3 rat:5,6B'::tsvector, 'A', '{cat,rat}')</literal> |
| <returnvalue>'cat':3A 'fat':2,4 'rat':5A,6A</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>strip</primary> |
| </indexterm> |
| <function>strip</function> ( <type>tsvector</type> ) |
| <returnvalue>tsvector</returnvalue> |
| </para> |
| <para> |
| Removes positions and weights from the <type>tsvector</type>. |
| </para> |
| <para> |
| <literal>strip('fat:2,4 cat:3 rat:5A'::tsvector)</literal> |
| <returnvalue>'cat' 'fat' 'rat'</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>to_tsquery</primary> |
| </indexterm> |
| <function>to_tsquery</function> ( |
| <optional> <parameter>config</parameter> <type>regconfig</type>, </optional> |
| <parameter>query</parameter> <type>text</type> ) |
| <returnvalue>tsquery</returnvalue> |
| </para> |
| <para> |
| Converts text to a <type>tsquery</type>, normalizing words according to |
| the specified or default configuration. The words must be combined |
| by valid <type>tsquery</type> operators. |
| </para> |
| <para> |
| <literal>to_tsquery('english', 'The & Fat & Rats')</literal> |
| <returnvalue>'fat' & 'rat'</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>to_tsvector</primary> |
| </indexterm> |
| <function>to_tsvector</function> ( |
| <optional> <parameter>config</parameter> <type>regconfig</type>, </optional> |
| <parameter>document</parameter> <type>text</type> ) |
| <returnvalue>tsvector</returnvalue> |
| </para> |
| <para> |
| Converts text to a <type>tsvector</type>, normalizing words according |
| to the specified or default configuration. Position information is |
| included in the result. |
| </para> |
| <para> |
| <literal>to_tsvector('english', 'The Fat Rats')</literal> |
| <returnvalue>'fat':2 'rat':3</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>to_tsvector</function> ( |
| <optional> <parameter>config</parameter> <type>regconfig</type>, </optional> |
| <parameter>document</parameter> <type>json</type> ) |
| <returnvalue>tsvector</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>to_tsvector</function> ( |
| <optional> <parameter>config</parameter> <type>regconfig</type>, </optional> |
| <parameter>document</parameter> <type>jsonb</type> ) |
| <returnvalue>tsvector</returnvalue> |
| </para> |
| <para> |
| Converts each string value in the JSON document to |
| a <type>tsvector</type>, normalizing words according to the specified |
| or default configuration. The results are then concatenated in |
| document order to produce the output. Position information is |
| generated as though one stopword exists between each pair of string |
| values. (Beware that <quote>document order</quote> of the fields of a |
| JSON object is implementation-dependent when the input |
| is <type>jsonb</type>; observe the difference in the examples.) |
| </para> |
| <para> |
| <literal>to_tsvector('english', '{"aa": "The Fat Rats", "b": "dog"}'::json)</literal> |
| <returnvalue>'dog':5 'fat':2 'rat':3</returnvalue> |
| </para> |
| <para> |
| <literal>to_tsvector('english', '{"aa": "The Fat Rats", "b": "dog"}'::jsonb)</literal> |
| <returnvalue>'dog':1 'fat':4 'rat':5</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>json_to_tsvector</primary> |
| </indexterm> |
| <function>json_to_tsvector</function> ( |
| <optional> <parameter>config</parameter> <type>regconfig</type>, </optional> |
| <parameter>document</parameter> <type>json</type>, |
| <parameter>filter</parameter> <type>jsonb</type> ) |
| <returnvalue>tsvector</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_to_tsvector</primary> |
| </indexterm> |
| <function>jsonb_to_tsvector</function> ( |
| <optional> <parameter>config</parameter> <type>regconfig</type>, </optional> |
| <parameter>document</parameter> <type>jsonb</type>, |
| <parameter>filter</parameter> <type>jsonb</type> ) |
| <returnvalue>tsvector</returnvalue> |
| </para> |
| <para> |
| Selects each item in the JSON document that is requested by |
| the <parameter>filter</parameter> and converts each one to |
| a <type>tsvector</type>, normalizing words according to the specified |
| or default configuration. The results are then concatenated in |
| document order to produce the output. Position information is |
| generated as though one stopword exists between each pair of selected |
| items. (Beware that <quote>document order</quote> of the fields of a |
| JSON object is implementation-dependent when the input |
| is <type>jsonb</type>.) |
| The <parameter>filter</parameter> must be a <type>jsonb</type> |
| array containing zero or more of these keywords: |
| <literal>"string"</literal> (to include all string values), |
| <literal>"numeric"</literal> (to include all numeric values), |
| <literal>"boolean"</literal> (to include all boolean values), |
| <literal>"key"</literal> (to include all keys), or |
| <literal>"all"</literal> (to include all the above). |
| As a special case, the <parameter>filter</parameter> can also be a |
| simple JSON value that is one of these keywords. |
| </para> |
| <para> |
| <literal>json_to_tsvector('english', '{"a": "The Fat Rats", "b": 123}'::json, '["string", "numeric"]')</literal> |
| <returnvalue>'123':5 'fat':2 'rat':3</returnvalue> |
| </para> |
| <para> |
| <literal>json_to_tsvector('english', '{"cat": "The Fat Rats", "dog": 123}'::json, '"all"')</literal> |
| <returnvalue>'123':9 'cat':1 'dog':7 'fat':4 'rat':5</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>ts_delete</primary> |
| </indexterm> |
| <function>ts_delete</function> ( <parameter>vector</parameter> <type>tsvector</type>, <parameter>lexeme</parameter> <type>text</type> ) |
| <returnvalue>tsvector</returnvalue> |
| </para> |
| <para> |
| Removes any occurrence of the given <parameter>lexeme</parameter> |
| from the <parameter>vector</parameter>. |
| </para> |
| <para> |
| <literal>ts_delete('fat:2,4 cat:3 rat:5A'::tsvector, 'fat')</literal> |
| <returnvalue>'cat':3 'rat':5A</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>ts_delete</function> ( <parameter>vector</parameter> <type>tsvector</type>, <parameter>lexemes</parameter> <type>text[]</type> ) |
| <returnvalue>tsvector</returnvalue> |
| </para> |
| <para> |
| Removes any occurrences of the lexemes |
| in <parameter>lexemes</parameter> |
| from the <parameter>vector</parameter>. |
| </para> |
| <para> |
| <literal>ts_delete('fat:2,4 cat:3 rat:5A'::tsvector, ARRAY['fat','rat'])</literal> |
| <returnvalue>'cat':3</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>ts_filter</primary> |
| </indexterm> |
| <function>ts_filter</function> ( <parameter>vector</parameter> <type>tsvector</type>, <parameter>weights</parameter> <type>"char"[]</type> ) |
| <returnvalue>tsvector</returnvalue> |
| </para> |
| <para> |
| Selects only elements with the given <parameter>weights</parameter> |
| from the <parameter>vector</parameter>. |
| </para> |
| <para> |
| <literal>ts_filter('fat:2,4 cat:3b,7c rat:5A'::tsvector, '{a,b}')</literal> |
| <returnvalue>'cat':3B 'rat':5A</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>ts_headline</primary> |
| </indexterm> |
| <function>ts_headline</function> ( |
| <optional> <parameter>config</parameter> <type>regconfig</type>, </optional> |
| <parameter>document</parameter> <type>text</type>, |
| <parameter>query</parameter> <type>tsquery</type> |
| <optional>, <parameter>options</parameter> <type>text</type> </optional> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Displays, in an abbreviated form, the match(es) for |
| the <parameter>query</parameter> in |
| the <parameter>document</parameter>, which must be raw text not |
| a <type>tsvector</type>. Words in the document are normalized |
| according to the specified or default configuration before matching to |
| the query. Use of this function is discussed in |
| <xref linkend="textsearch-headline"/>, which also describes the |
| available <parameter>options</parameter>. |
| </para> |
| <para> |
| <literal>ts_headline('The fat cat ate the rat.', 'cat')</literal> |
| <returnvalue>The fat <b>cat</b> ate the rat.</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>ts_headline</function> ( |
| <optional> <parameter>config</parameter> <type>regconfig</type>, </optional> |
| <parameter>document</parameter> <type>json</type>, |
| <parameter>query</parameter> <type>tsquery</type> |
| <optional>, <parameter>options</parameter> <type>text</type> </optional> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>ts_headline</function> ( |
| <optional> <parameter>config</parameter> <type>regconfig</type>, </optional> |
| <parameter>document</parameter> <type>jsonb</type>, |
| <parameter>query</parameter> <type>tsquery</type> |
| <optional>, <parameter>options</parameter> <type>text</type> </optional> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Displays, in an abbreviated form, match(es) for |
| the <parameter>query</parameter> that occur in string values |
| within the JSON <parameter>document</parameter>. |
| See <xref linkend="textsearch-headline"/> for more details. |
| </para> |
| <para> |
| <literal>ts_headline('{"cat":"raining cats and dogs"}'::jsonb, 'cat')</literal> |
| <returnvalue>{"cat": "raining <b>cats</b> and dogs"}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>ts_rank</primary> |
| </indexterm> |
| <function>ts_rank</function> ( |
| <optional> <parameter>weights</parameter> <type>real[]</type>, </optional> |
| <parameter>vector</parameter> <type>tsvector</type>, |
| <parameter>query</parameter> <type>tsquery</type> |
| <optional>, <parameter>normalization</parameter> <type>integer</type> </optional> ) |
| <returnvalue>real</returnvalue> |
| </para> |
| <para> |
| Computes a score showing how well |
| the <parameter>vector</parameter> matches |
| the <parameter>query</parameter>. See |
| <xref linkend="textsearch-ranking"/> for details. |
| </para> |
| <para> |
| <literal>ts_rank(to_tsvector('raining cats and dogs'), 'cat')</literal> |
| <returnvalue>0.06079271</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>ts_rank_cd</primary> |
| </indexterm> |
| <function>ts_rank_cd</function> ( |
| <optional> <parameter>weights</parameter> <type>real[]</type>, </optional> |
| <parameter>vector</parameter> <type>tsvector</type>, |
| <parameter>query</parameter> <type>tsquery</type> |
| <optional>, <parameter>normalization</parameter> <type>integer</type> </optional> ) |
| <returnvalue>real</returnvalue> |
| </para> |
| <para> |
| Computes a score showing how well |
| the <parameter>vector</parameter> matches |
| the <parameter>query</parameter>, using a cover density |
| algorithm. See <xref linkend="textsearch-ranking"/> for details. |
| </para> |
| <para> |
| <literal>ts_rank_cd(to_tsvector('raining cats and dogs'), 'cat')</literal> |
| <returnvalue>0.1</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>ts_rewrite</primary> |
| </indexterm> |
| <function>ts_rewrite</function> ( <parameter>query</parameter> <type>tsquery</type>, |
| <parameter>target</parameter> <type>tsquery</type>, |
| <parameter>substitute</parameter> <type>tsquery</type> ) |
| <returnvalue>tsquery</returnvalue> |
| </para> |
| <para> |
| Replaces occurrences of <parameter>target</parameter> |
| with <parameter>substitute</parameter> |
| within the <parameter>query</parameter>. |
| See <xref linkend="textsearch-query-rewriting"/> for details. |
| </para> |
| <para> |
| <literal>ts_rewrite('a & b'::tsquery, 'a'::tsquery, 'foo|bar'::tsquery)</literal> |
| <returnvalue>'b' & ( 'foo' | 'bar' )</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>ts_rewrite</function> ( <parameter>query</parameter> <type>tsquery</type>, |
| <parameter>select</parameter> <type>text</type> ) |
| <returnvalue>tsquery</returnvalue> |
| </para> |
| <para> |
| Replaces portions of the <parameter>query</parameter> according to |
| target(s) and substitute(s) obtained by executing |
| a <command>SELECT</command> command. |
| See <xref linkend="textsearch-query-rewriting"/> for details. |
| </para> |
| <para> |
| <literal>SELECT ts_rewrite('a & b'::tsquery, 'SELECT t,s FROM aliases')</literal> |
| <returnvalue>'b' & ( 'foo' | 'bar' )</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>tsquery_phrase</primary> |
| </indexterm> |
| <function>tsquery_phrase</function> ( <parameter>query1</parameter> <type>tsquery</type>, <parameter>query2</parameter> <type>tsquery</type> ) |
| <returnvalue>tsquery</returnvalue> |
| </para> |
| <para> |
| Constructs a phrase query that searches |
| for matches of <parameter>query1</parameter> |
| and <parameter>query2</parameter> at successive lexemes (same |
| as <literal><-></literal> operator). |
| </para> |
| <para> |
| <literal>tsquery_phrase(to_tsquery('fat'), to_tsquery('cat'))</literal> |
| <returnvalue>'fat' <-> 'cat'</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>tsquery_phrase</function> ( <parameter>query1</parameter> <type>tsquery</type>, <parameter>query2</parameter> <type>tsquery</type>, <parameter>distance</parameter> <type>integer</type> ) |
| <returnvalue>tsquery</returnvalue> |
| </para> |
| <para> |
| Constructs a phrase query that searches |
| for matches of <parameter>query1</parameter> and |
| <parameter>query2</parameter> that occur exactly |
| <parameter>distance</parameter> lexemes apart. |
| </para> |
| <para> |
| <literal>tsquery_phrase(to_tsquery('fat'), to_tsquery('cat'), 10)</literal> |
| <returnvalue>'fat' <10> 'cat'</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>tsvector_to_array</primary> |
| </indexterm> |
| <function>tsvector_to_array</function> ( <type>tsvector</type> ) |
| <returnvalue>text[]</returnvalue> |
| </para> |
| <para> |
| Converts a <type>tsvector</type> to an array of lexemes. |
| </para> |
| <para> |
| <literal>tsvector_to_array('fat:2,4 cat:3 rat:5A'::tsvector)</literal> |
| <returnvalue>{cat,fat,rat}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>unnest</primary> |
| <secondary>for tsvector</secondary> |
| </indexterm> |
| <function>unnest</function> ( <type>tsvector</type> ) |
| <returnvalue>setof record</returnvalue> |
| ( <parameter>lexeme</parameter> <type>text</type>, |
| <parameter>positions</parameter> <type>smallint[]</type>, |
| <parameter>weights</parameter> <type>text</type> ) |
| </para> |
| <para> |
| Expands a <type>tsvector</type> into a set of rows, one per lexeme. |
| </para> |
| <para> |
| <literal>select * from unnest('cat:3 fat:2,4 rat:5A'::tsvector)</literal> |
| <returnvalue></returnvalue> |
| <programlisting> |
| lexeme | positions | weights |
| --------+-----------+--------- |
| cat | {3} | {D} |
| fat | {2,4} | {D,D} |
| rat | {5} | {A} |
| </programlisting> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <note> |
| <para> |
| All the text search functions that accept an optional <type>regconfig</type> |
| argument will use the configuration specified by |
| <xref linkend="guc-default-text-search-config"/> |
| when that argument is omitted. |
| </para> |
| </note> |
| |
| <para> |
| The functions in |
| <xref linkend="textsearch-functions-debug-table"/> |
| are listed separately because they are not usually used in everyday text |
| searching operations. They are primarily helpful for development and |
| debugging of new text search configurations. |
| </para> |
| |
| <table id="textsearch-functions-debug-table"> |
| <title>Text Search Debugging Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>ts_debug</primary> |
| </indexterm> |
| <function>ts_debug</function> ( |
| <optional> <parameter>config</parameter> <type>regconfig</type>, </optional> |
| <parameter>document</parameter> <type>text</type> ) |
| <returnvalue>setof record</returnvalue> |
| ( <parameter>alias</parameter> <type>text</type>, |
| <parameter>description</parameter> <type>text</type>, |
| <parameter>token</parameter> <type>text</type>, |
| <parameter>dictionaries</parameter> <type>regdictionary[]</type>, |
| <parameter>dictionary</parameter> <type>regdictionary</type>, |
| <parameter>lexemes</parameter> <type>text[]</type> ) |
| </para> |
| <para> |
| Extracts and normalizes tokens from |
| the <parameter>document</parameter> according to the specified or |
| default text search configuration, and returns information about how |
| each token was processed. |
| See <xref linkend="textsearch-configuration-testing"/> for details. |
| </para> |
| <para> |
| <literal>ts_debug('english', 'The Brightest supernovaes')</literal> |
| <returnvalue>(asciiword,"Word, all ASCII",The,{english_stem},english_stem,{}) ...</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>ts_lexize</primary> |
| </indexterm> |
| <function>ts_lexize</function> ( <parameter>dict</parameter> <type>regdictionary</type>, <parameter>token</parameter> <type>text</type> ) |
| <returnvalue>text[]</returnvalue> |
| </para> |
| <para> |
| Returns an array of replacement lexemes if the input token is known to |
| the dictionary, or an empty array if the token is known to the |
| dictionary but it is a stop word, or NULL if it is not a known word. |
| See <xref linkend="textsearch-dictionary-testing"/> for details. |
| </para> |
| <para> |
| <literal>ts_lexize('english_stem', 'stars')</literal> |
| <returnvalue>{star}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>ts_parse</primary> |
| </indexterm> |
| <function>ts_parse</function> ( <parameter>parser_name</parameter> <type>text</type>, |
| <parameter>document</parameter> <type>text</type> ) |
| <returnvalue>setof record</returnvalue> |
| ( <parameter>tokid</parameter> <type>integer</type>, |
| <parameter>token</parameter> <type>text</type> ) |
| </para> |
| <para> |
| Extracts tokens from the <parameter>document</parameter> using the |
| named parser. |
| See <xref linkend="textsearch-parser-testing"/> for details. |
| </para> |
| <para> |
| <literal>ts_parse('default', 'foo - bar')</literal> |
| <returnvalue>(1,foo) ...</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>ts_parse</function> ( <parameter>parser_oid</parameter> <type>oid</type>, |
| <parameter>document</parameter> <type>text</type> ) |
| <returnvalue>setof record</returnvalue> |
| ( <parameter>tokid</parameter> <type>integer</type>, |
| <parameter>token</parameter> <type>text</type> ) |
| </para> |
| <para> |
| Extracts tokens from the <parameter>document</parameter> using a |
| parser specified by OID. |
| See <xref linkend="textsearch-parser-testing"/> for details. |
| </para> |
| <para> |
| <literal>ts_parse(3722, 'foo - bar')</literal> |
| <returnvalue>(1,foo) ...</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>ts_token_type</primary> |
| </indexterm> |
| <function>ts_token_type</function> ( <parameter>parser_name</parameter> <type>text</type> ) |
| <returnvalue>setof record</returnvalue> |
| ( <parameter>tokid</parameter> <type>integer</type>, |
| <parameter>alias</parameter> <type>text</type>, |
| <parameter>description</parameter> <type>text</type> ) |
| </para> |
| <para> |
| Returns a table that describes each type of token the named parser can |
| recognize. |
| See <xref linkend="textsearch-parser-testing"/> for details. |
| </para> |
| <para> |
| <literal>ts_token_type('default')</literal> |
| <returnvalue>(1,asciiword,"Word, all ASCII") ...</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>ts_token_type</function> ( <parameter>parser_oid</parameter> <type>oid</type> ) |
| <returnvalue>setof record</returnvalue> |
| ( <parameter>tokid</parameter> <type>integer</type>, |
| <parameter>alias</parameter> <type>text</type>, |
| <parameter>description</parameter> <type>text</type> ) |
| </para> |
| <para> |
| Returns a table that describes each type of token a parser specified |
| by OID can recognize. |
| See <xref linkend="textsearch-parser-testing"/> for details. |
| </para> |
| <para> |
| <literal>ts_token_type(3722)</literal> |
| <returnvalue>(1,asciiword,"Word, all ASCII") ...</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>ts_stat</primary> |
| </indexterm> |
| <function>ts_stat</function> ( <parameter>sqlquery</parameter> <type>text</type> |
| <optional>, <parameter>weights</parameter> <type>text</type> </optional> ) |
| <returnvalue>setof record</returnvalue> |
| ( <parameter>word</parameter> <type>text</type>, |
| <parameter>ndoc</parameter> <type>integer</type>, |
| <parameter>nentry</parameter> <type>integer</type> ) |
| </para> |
| <para> |
| Executes the <parameter>sqlquery</parameter>, which must return a |
| single <type>tsvector</type> column, and returns statistics about each |
| distinct lexeme contained in the data. |
| See <xref linkend="textsearch-statistics"/> for details. |
| </para> |
| <para> |
| <literal>ts_stat('SELECT vector FROM apod')</literal> |
| <returnvalue>(foo,10,15) ...</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| </sect1> |
| |
| <sect1 id="functions-uuid"> |
| <title>UUID Functions</title> |
| |
| <indexterm zone="datatype-uuid"> |
| <primary>UUID</primary> |
| <secondary>generating</secondary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>gen_random_uuid</primary> |
| </indexterm> |
| |
| <para> |
| <productname>PostgreSQL</productname> includes one function to generate a UUID: |
| <synopsis> |
| <function>gen_random_uuid</function> () <returnvalue>uuid</returnvalue> |
| </synopsis> |
| This function returns a version 4 (random) UUID. This is the most commonly |
| used type of UUID and is appropriate for most applications. |
| </para> |
| |
| <para> |
| The <xref linkend="uuid-ossp"/> module provides additional functions that |
| implement other standard algorithms for generating UUIDs. |
| </para> |
| |
| <para> |
| <productname>PostgreSQL</productname> also provides the usual comparison |
| operators shown in <xref linkend="functions-comparison-op-table"/> for |
| UUIDs. |
| </para> |
| </sect1> |
| |
| <sect1 id="functions-xml"> |
| |
| <title>XML Functions</title> |
| |
| <indexterm> |
| <primary>XML Functions</primary> |
| </indexterm> |
| |
| <para> |
| The functions and function-like expressions described in this |
| section operate on values of type <type>xml</type>. See <xref |
| linkend="datatype-xml"/> for information about the <type>xml</type> |
| type. The function-like expressions <function>xmlparse</function> |
| and <function>xmlserialize</function> for converting to and from |
| type <type>xml</type> are documented there, not in this section. |
| </para> |
| |
| <para> |
| Use of most of these functions |
| requires <productname>PostgreSQL</productname> to have been built |
| with <command>configure --with-libxml</command>. |
| </para> |
| |
| <sect2 id="functions-producing-xml"> |
| <title>Producing XML Content</title> |
| |
| <para> |
| A set of functions and function-like expressions is available for |
| producing XML content from SQL data. As such, they are |
| particularly suitable for formatting query results into XML |
| documents for processing in client applications. |
| </para> |
| |
| <sect3> |
| <title><literal>xmlcomment</literal></title> |
| |
| <indexterm> |
| <primary>xmlcomment</primary> |
| </indexterm> |
| |
| <synopsis> |
| <function>xmlcomment</function> ( <type>text</type> ) <returnvalue>xml</returnvalue> |
| </synopsis> |
| |
| <para> |
| The function <function>xmlcomment</function> creates an XML value |
| containing an XML comment with the specified text as content. |
| The text cannot contain <quote><literal>--</literal></quote> or end with a |
| <quote><literal>-</literal></quote>, otherwise the resulting construct |
| would not be a valid XML comment. |
| If the argument is null, the result is null. |
| </para> |
| |
| <para> |
| Example: |
| <screen><![CDATA[ |
| SELECT xmlcomment('hello'); |
| |
| xmlcomment |
| -------------- |
| <!--hello--> |
| ]]></screen> |
| </para> |
| </sect3> |
| |
| <sect3> |
| <title><literal>xmlconcat</literal></title> |
| |
| <indexterm> |
| <primary>xmlconcat</primary> |
| </indexterm> |
| |
| <synopsis> |
| <function>xmlconcat</function> ( <type>xml</type> <optional>, ...</optional> ) <returnvalue>xml</returnvalue> |
| </synopsis> |
| |
| <para> |
| The function <function>xmlconcat</function> concatenates a list |
| of individual XML values to create a single value containing an |
| XML content fragment. Null values are omitted; the result is |
| only null if there are no nonnull arguments. |
| </para> |
| |
| <para> |
| Example: |
| <screen><![CDATA[ |
| SELECT xmlconcat('<abc/>', '<bar>foo</bar>'); |
| |
| xmlconcat |
| ---------------------- |
| <abc/><bar>foo</bar> |
| ]]></screen> |
| </para> |
| |
| <para> |
| XML declarations, if present, are combined as follows. If all |
| argument values have the same XML version declaration, that |
| version is used in the result, else no version is used. If all |
| argument values have the standalone declaration value |
| <quote>yes</quote>, then that value is used in the result. If |
| all argument values have a standalone declaration value and at |
| least one is <quote>no</quote>, then that is used in the result. |
| Else the result will have no standalone declaration. If the |
| result is determined to require a standalone declaration but no |
| version declaration, a version declaration with version 1.0 will |
| be used because XML requires an XML declaration to contain a |
| version declaration. Encoding declarations are ignored and |
| removed in all cases. |
| </para> |
| |
| <para> |
| Example: |
| <screen><![CDATA[ |
| SELECT xmlconcat('<?xml version="1.1"?><foo/>', '<?xml version="1.1" standalone="no"?><bar/>'); |
| |
| xmlconcat |
| ----------------------------------- |
| <?xml version="1.1"?><foo/><bar/> |
| ]]></screen> |
| </para> |
| </sect3> |
| |
| <sect3> |
| <title><literal>xmlelement</literal></title> |
| |
| <indexterm> |
| <primary>xmlelement</primary> |
| </indexterm> |
| |
| <synopsis> |
| <function>xmlelement</function> ( <literal>NAME</literal> <replaceable>name</replaceable> <optional>, <literal>XMLATTRIBUTES</literal> ( <replaceable>attvalue</replaceable> <optional> <literal>AS</literal> <replaceable>attname</replaceable> </optional> <optional>, ...</optional> ) </optional> <optional>, <replaceable>content</replaceable> <optional>, ...</optional></optional> ) <returnvalue>xml</returnvalue> |
| </synopsis> |
| |
| <para> |
| The <function>xmlelement</function> expression produces an XML |
| element with the given name, attributes, and content. |
| The <replaceable>name</replaceable> |
| and <replaceable>attname</replaceable> items shown in the syntax are |
| simple identifiers, not values. The <replaceable>attvalue</replaceable> |
| and <replaceable>content</replaceable> items are expressions, which can |
| yield any <productname>PostgreSQL</productname> data type. The |
| argument(s) within <literal>XMLATTRIBUTES</literal> generate attributes |
| of the XML element; the <replaceable>content</replaceable> value(s) are |
| concatenated to form its content. |
| </para> |
| |
| <para> |
| Examples: |
| <screen><![CDATA[ |
| SELECT xmlelement(name foo); |
| |
| xmlelement |
| ------------ |
| <foo/> |
| |
| SELECT xmlelement(name foo, xmlattributes('xyz' as bar)); |
| |
| xmlelement |
| ------------------ |
| <foo bar="xyz"/> |
| |
| SELECT xmlelement(name foo, xmlattributes(current_date as bar), 'cont', 'ent'); |
| |
| xmlelement |
| ------------------------------------- |
| <foo bar="2007-01-26">content</foo> |
| ]]></screen> |
| </para> |
| |
| <para> |
| Element and attribute names that are not valid XML names are |
| escaped by replacing the offending characters by the sequence |
| <literal>_x<replaceable>HHHH</replaceable>_</literal>, where |
| <replaceable>HHHH</replaceable> is the character's Unicode |
| codepoint in hexadecimal notation. For example: |
| <screen><![CDATA[ |
| SELECT xmlelement(name "foo$bar", xmlattributes('xyz' as "a&b")); |
| |
| xmlelement |
| ---------------------------------- |
| <foo_x0024_bar a_x0026_b="xyz"/> |
| ]]></screen> |
| </para> |
| |
| <para> |
| An explicit attribute name need not be specified if the attribute |
| value is a column reference, in which case the column's name will |
| be used as the attribute name by default. In other cases, the |
| attribute must be given an explicit name. So this example is |
| valid: |
| <screen> |
| CREATE TABLE test (a xml, b xml); |
| SELECT xmlelement(name test, xmlattributes(a, b)) FROM test; |
| </screen> |
| But these are not: |
| <screen> |
| SELECT xmlelement(name test, xmlattributes('constant'), a, b) FROM test; |
| SELECT xmlelement(name test, xmlattributes(func(a, b))) FROM test; |
| </screen> |
| </para> |
| |
| <para> |
| Element content, if specified, will be formatted according to |
| its data type. If the content is itself of type <type>xml</type>, |
| complex XML documents can be constructed. For example: |
| <screen><![CDATA[ |
| SELECT xmlelement(name foo, xmlattributes('xyz' as bar), |
| xmlelement(name abc), |
| xmlcomment('test'), |
| xmlelement(name xyz)); |
| |
| xmlelement |
| ---------------------------------------------- |
| <foo bar="xyz"><abc/><!--test--><xyz/></foo> |
| ]]></screen> |
| |
| Content of other types will be formatted into valid XML character |
| data. This means in particular that the characters <, >, |
| and & will be converted to entities. Binary data (data type |
| <type>bytea</type>) will be represented in base64 or hex |
| encoding, depending on the setting of the configuration parameter |
| <xref linkend="guc-xmlbinary"/>. The particular behavior for |
| individual data types is expected to evolve in order to align the |
| PostgreSQL mappings with those specified in SQL:2006 and later, |
| as discussed in <xref linkend="functions-xml-limits-casts"/>. |
| </para> |
| </sect3> |
| |
| <sect3> |
| <title><literal>xmlforest</literal></title> |
| |
| <indexterm> |
| <primary>xmlforest</primary> |
| </indexterm> |
| |
| <synopsis> |
| <function>xmlforest</function> ( <replaceable>content</replaceable> <optional> <literal>AS</literal> <replaceable>name</replaceable> </optional> <optional>, ...</optional> ) <returnvalue>xml</returnvalue> |
| </synopsis> |
| |
| <para> |
| The <function>xmlforest</function> expression produces an XML |
| forest (sequence) of elements using the given names and content. |
| As for <function>xmlelement</function>, |
| each <replaceable>name</replaceable> must be a simple identifier, while |
| the <replaceable>content</replaceable> expressions can have any data |
| type. |
| </para> |
| |
| <para> |
| Examples: |
| <screen> |
| SELECT xmlforest('abc' AS foo, 123 AS bar); |
| |
| xmlforest |
| ------------------------------ |
| <foo>abc</foo><bar>123</bar> |
| |
| |
| SELECT xmlforest(table_name, column_name) |
| FROM information_schema.columns |
| WHERE table_schema = 'pg_catalog'; |
| |
| xmlforest |
| ------------------------------------&zwsp;----------------------------------- |
| <table_name>pg_authid</table_name>&zwsp;<column_name>rolname</column_name> |
| <table_name>pg_authid</table_name>&zwsp;<column_name>rolsuper</column_name> |
| ... |
| </screen> |
| |
| As seen in the second example, the element name can be omitted if |
| the content value is a column reference, in which case the column |
| name is used by default. Otherwise, a name must be specified. |
| </para> |
| |
| <para> |
| Element names that are not valid XML names are escaped as shown |
| for <function>xmlelement</function> above. Similarly, content |
| data is escaped to make valid XML content, unless it is already |
| of type <type>xml</type>. |
| </para> |
| |
| <para> |
| Note that XML forests are not valid XML documents if they consist |
| of more than one element, so it might be useful to wrap |
| <function>xmlforest</function> expressions in |
| <function>xmlelement</function>. |
| </para> |
| </sect3> |
| |
| <sect3> |
| <title><literal>xmlpi</literal></title> |
| |
| <indexterm> |
| <primary>xmlpi</primary> |
| </indexterm> |
| |
| <synopsis> |
| <function>xmlpi</function> ( <literal>NAME</literal> <replaceable>name</replaceable> <optional>, <replaceable>content</replaceable> </optional> ) <returnvalue>xml</returnvalue> |
| </synopsis> |
| |
| <para> |
| The <function>xmlpi</function> expression creates an XML |
| processing instruction. |
| As for <function>xmlelement</function>, |
| the <replaceable>name</replaceable> must be a simple identifier, while |
| the <replaceable>content</replaceable> expression can have any data type. |
| The <replaceable>content</replaceable>, if present, must not contain the |
| character sequence <literal>?></literal>. |
| </para> |
| |
| <para> |
| Example: |
| <screen><![CDATA[ |
| SELECT xmlpi(name php, 'echo "hello world";'); |
| |
| xmlpi |
| ----------------------------- |
| <?php echo "hello world";?> |
| ]]></screen> |
| </para> |
| </sect3> |
| |
| <sect3> |
| <title><literal>xmlroot</literal></title> |
| |
| <indexterm> |
| <primary>xmlroot</primary> |
| </indexterm> |
| |
| <synopsis> |
| <function>xmlroot</function> ( <type>xml</type>, <literal>VERSION</literal> {<type>text</type>|<literal>NO VALUE</literal>} <optional>, <literal>STANDALONE</literal> {<literal>YES</literal>|<literal>NO</literal>|<literal>NO VALUE</literal>} </optional> ) <returnvalue>xml</returnvalue> |
| </synopsis> |
| |
| <para> |
| The <function>xmlroot</function> expression alters the properties |
| of the root node of an XML value. If a version is specified, |
| it replaces the value in the root node's version declaration; if a |
| standalone setting is specified, it replaces the value in the |
| root node's standalone declaration. |
| </para> |
| |
| <para> |
| <screen><![CDATA[ |
| SELECT xmlroot(xmlparse(document '<?xml version="1.1"?><content>abc</content>'), |
| version '1.0', standalone yes); |
| |
| xmlroot |
| ---------------------------------------- |
| <?xml version="1.0" standalone="yes"?> |
| <content>abc</content> |
| ]]></screen> |
| </para> |
| </sect3> |
| |
| <sect3 id="functions-xml-xmlagg"> |
| <title><literal>xmlagg</literal></title> |
| |
| <indexterm> |
| <primary>xmlagg</primary> |
| </indexterm> |
| |
| <synopsis> |
| <function>xmlagg</function> ( <type>xml</type> ) <returnvalue>xml</returnvalue> |
| </synopsis> |
| |
| <para> |
| The function <function>xmlagg</function> is, unlike the other |
| functions described here, an aggregate function. It concatenates the |
| input values to the aggregate function call, |
| much like <function>xmlconcat</function> does, except that concatenation |
| occurs across rows rather than across expressions in a single row. |
| See <xref linkend="functions-aggregate"/> for additional information |
| about aggregate functions. |
| </para> |
| |
| <para> |
| Example: |
| <screen><![CDATA[ |
| CREATE TABLE test (y int, x xml); |
| INSERT INTO test VALUES (1, '<foo>abc</foo>'); |
| INSERT INTO test VALUES (2, '<bar/>'); |
| SELECT xmlagg(x) FROM test; |
| xmlagg |
| ---------------------- |
| <foo>abc</foo><bar/> |
| ]]></screen> |
| </para> |
| |
| <para> |
| To determine the order of the concatenation, an <literal>ORDER BY</literal> |
| clause may be added to the aggregate call as described in |
| <xref linkend="syntax-aggregates"/>. For example: |
| |
| <screen><![CDATA[ |
| SELECT xmlagg(x ORDER BY y DESC) FROM test; |
| xmlagg |
| ---------------------- |
| <bar/><foo>abc</foo> |
| ]]></screen> |
| </para> |
| |
| <para> |
| The following non-standard approach used to be recommended |
| in previous versions, and may still be useful in specific |
| cases: |
| |
| <screen><![CDATA[ |
| SELECT xmlagg(x) FROM (SELECT * FROM test ORDER BY y DESC) AS tab; |
| xmlagg |
| ---------------------- |
| <bar/><foo>abc</foo> |
| ]]></screen> |
| </para> |
| </sect3> |
| </sect2> |
| |
| <sect2 id="functions-xml-predicates"> |
| <title>XML Predicates</title> |
| |
| <para> |
| The expressions described in this section check properties |
| of <type>xml</type> values. |
| </para> |
| |
| <sect3> |
| <title><literal>IS DOCUMENT</literal></title> |
| |
| <indexterm> |
| <primary>IS DOCUMENT</primary> |
| </indexterm> |
| |
| <synopsis> |
| <type>xml</type> <literal>IS DOCUMENT</literal> <returnvalue>boolean</returnvalue> |
| </synopsis> |
| |
| <para> |
| The expression <literal>IS DOCUMENT</literal> returns true if the |
| argument XML value is a proper XML document, false if it is not |
| (that is, it is a content fragment), or null if the argument is |
| null. See <xref linkend="datatype-xml"/> about the difference |
| between documents and content fragments. |
| </para> |
| </sect3> |
| |
| <sect3> |
| <title><literal>IS NOT DOCUMENT</literal></title> |
| |
| <indexterm> |
| <primary>IS NOT DOCUMENT</primary> |
| </indexterm> |
| |
| <synopsis> |
| <type>xml</type> <literal>IS NOT DOCUMENT</literal> <returnvalue>boolean</returnvalue> |
| </synopsis> |
| |
| <para> |
| The expression <literal>IS NOT DOCUMENT</literal> returns false if the |
| argument XML value is a proper XML document, true if it is not (that is, |
| it is a content fragment), or null if the argument is null. |
| </para> |
| </sect3> |
| |
| <sect3 id="xml-exists"> |
| <title><literal>XMLEXISTS</literal></title> |
| |
| <indexterm> |
| <primary>XMLEXISTS</primary> |
| </indexterm> |
| |
| <synopsis> |
| <function>XMLEXISTS</function> ( <type>text</type> <literal>PASSING</literal> <optional><literal>BY</literal> {<literal>REF</literal>|<literal>VALUE</literal>}</optional> <type>xml</type> <optional><literal>BY</literal> {<literal>REF</literal>|<literal>VALUE</literal>}</optional> ) <returnvalue>boolean</returnvalue> |
| </synopsis> |
| |
| <para> |
| The function <function>xmlexists</function> evaluates an XPath 1.0 |
| expression (the first argument), with the passed XML value as its context |
| item. The function returns false if the result of that evaluation |
| yields an empty node-set, true if it yields any other value. The |
| function returns null if any argument is null. A nonnull value |
| passed as the context item must be an XML document, not a content |
| fragment or any non-XML value. |
| </para> |
| |
| <para> |
| Example: |
| <screen><![CDATA[ |
| SELECT xmlexists('//town[text() = ''Toronto'']' PASSING BY VALUE '<towns><town>Toronto</town><town>Ottawa</town></towns>'); |
| |
| xmlexists |
| ------------ |
| t |
| (1 row) |
| ]]></screen> |
| </para> |
| |
| <para> |
| The <literal>BY REF</literal> and <literal>BY VALUE</literal> clauses |
| are accepted in <productname>PostgreSQL</productname>, but are ignored, |
| as discussed in <xref linkend="functions-xml-limits-postgresql"/>. |
| </para> |
| |
| <para> |
| In the SQL standard, the <function>xmlexists</function> function |
| evaluates an expression in the XML Query language, |
| but <productname>PostgreSQL</productname> allows only an XPath 1.0 |
| expression, as discussed in |
| <xref linkend="functions-xml-limits-xpath1"/>. |
| </para> |
| </sect3> |
| |
| <sect3 id="xml-is-well-formed"> |
| <title><literal>xml_is_well_formed</literal></title> |
| |
| <indexterm> |
| <primary>xml_is_well_formed</primary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>xml_is_well_formed_document</primary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>xml_is_well_formed_content</primary> |
| </indexterm> |
| |
| <synopsis> |
| <function>xml_is_well_formed</function> ( <type>text</type> ) <returnvalue>boolean</returnvalue> |
| <function>xml_is_well_formed_document</function> ( <type>text</type> ) <returnvalue>boolean</returnvalue> |
| <function>xml_is_well_formed_content</function> ( <type>text</type> ) <returnvalue>boolean</returnvalue> |
| </synopsis> |
| |
| <para> |
| These functions check whether a <type>text</type> string represents |
| well-formed XML, returning a Boolean result. |
| <function>xml_is_well_formed_document</function> checks for a well-formed |
| document, while <function>xml_is_well_formed_content</function> checks |
| for well-formed content. <function>xml_is_well_formed</function> does |
| the former if the <xref linkend="guc-xmloption"/> configuration |
| parameter is set to <literal>DOCUMENT</literal>, or the latter if it is set to |
| <literal>CONTENT</literal>. This means that |
| <function>xml_is_well_formed</function> is useful for seeing whether |
| a simple cast to type <type>xml</type> will succeed, whereas the other two |
| functions are useful for seeing whether the corresponding variants of |
| <function>XMLPARSE</function> will succeed. |
| </para> |
| |
| <para> |
| Examples: |
| |
| <screen><![CDATA[ |
| SET xmloption TO DOCUMENT; |
| SELECT xml_is_well_formed('<>'); |
| xml_is_well_formed |
| -------------------- |
| f |
| (1 row) |
| |
| SELECT xml_is_well_formed('<abc/>'); |
| xml_is_well_formed |
| -------------------- |
| t |
| (1 row) |
| |
| SET xmloption TO CONTENT; |
| SELECT xml_is_well_formed('abc'); |
| xml_is_well_formed |
| -------------------- |
| t |
| (1 row) |
| |
| SELECT xml_is_well_formed_document('<pg:foo xmlns:pg="http://postgresql.org/stuff">bar</pg:foo>'); |
| xml_is_well_formed_document |
| ----------------------------- |
| t |
| (1 row) |
| |
| SELECT xml_is_well_formed_document('<pg:foo xmlns:pg="http://postgresql.org/stuff">bar</my:foo>'); |
| xml_is_well_formed_document |
| ----------------------------- |
| f |
| (1 row) |
| ]]></screen> |
| |
| The last example shows that the checks include whether |
| namespaces are correctly matched. |
| </para> |
| </sect3> |
| </sect2> |
| |
| <sect2 id="functions-xml-processing"> |
| <title>Processing XML</title> |
| |
| <para> |
| To process values of data type <type>xml</type>, PostgreSQL offers |
| the functions <function>xpath</function> and |
| <function>xpath_exists</function>, which evaluate XPath 1.0 |
| expressions, and the <function>XMLTABLE</function> |
| table function. |
| </para> |
| |
| <sect3 id="functions-xml-processing-xpath"> |
| <title><literal>xpath</literal></title> |
| |
| <indexterm> |
| <primary>XPath</primary> |
| </indexterm> |
| |
| <synopsis> |
| <function>xpath</function> ( <parameter>xpath</parameter> <type>text</type>, <parameter>xml</parameter> <type>xml</type> <optional>, <parameter>nsarray</parameter> <type>text[]</type> </optional> ) <returnvalue>xml[]</returnvalue> |
| </synopsis> |
| |
| <para> |
| The function <function>xpath</function> evaluates the XPath 1.0 |
| expression <parameter>xpath</parameter> (given as text) |
| against the XML value |
| <parameter>xml</parameter>. It returns an array of XML values |
| corresponding to the node-set produced by the XPath expression. |
| If the XPath expression returns a scalar value rather than a node-set, |
| a single-element array is returned. |
| </para> |
| |
| <para> |
| The second argument must be a well formed XML document. In particular, |
| it must have a single root node element. |
| </para> |
| |
| <para> |
| The optional third argument of the function is an array of namespace |
| mappings. This array should be a two-dimensional <type>text</type> array with |
| the length of the second axis being equal to 2 (i.e., it should be an |
| array of arrays, each of which consists of exactly 2 elements). |
| The first element of each array entry is the namespace name (alias), the |
| second the namespace URI. It is not required that aliases provided in |
| this array be the same as those being used in the XML document itself (in |
| other words, both in the XML document and in the <function>xpath</function> |
| function context, aliases are <emphasis>local</emphasis>). |
| </para> |
| |
| <para> |
| Example: |
| <screen><![CDATA[ |
| SELECT xpath('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>', |
| ARRAY[ARRAY['my', 'http://example.com']]); |
| |
| xpath |
| -------- |
| {test} |
| (1 row) |
| ]]></screen> |
| </para> |
| |
| <para> |
| To deal with default (anonymous) namespaces, do something like this: |
| <screen><![CDATA[ |
| SELECT xpath('//mydefns:b/text()', '<a xmlns="http://example.com"><b>test</b></a>', |
| ARRAY[ARRAY['mydefns', 'http://example.com']]); |
| |
| xpath |
| -------- |
| {test} |
| (1 row) |
| ]]></screen> |
| </para> |
| </sect3> |
| |
| <sect3 id="functions-xml-processing-xpath-exists"> |
| <title><literal>xpath_exists</literal></title> |
| |
| <indexterm> |
| <primary>xpath_exists</primary> |
| </indexterm> |
| |
| <synopsis> |
| <function>xpath_exists</function> ( <parameter>xpath</parameter> <type>text</type>, <parameter>xml</parameter> <type>xml</type> <optional>, <parameter>nsarray</parameter> <type>text[]</type> </optional> ) <returnvalue>boolean</returnvalue> |
| </synopsis> |
| |
| <para> |
| The function <function>xpath_exists</function> is a specialized form |
| of the <function>xpath</function> function. Instead of returning the |
| individual XML values that satisfy the XPath 1.0 expression, this function |
| returns a Boolean indicating whether the query was satisfied or not |
| (specifically, whether it produced any value other than an empty node-set). |
| This function is equivalent to the <literal>XMLEXISTS</literal> predicate, |
| except that it also offers support for a namespace mapping argument. |
| </para> |
| |
| <para> |
| Example: |
| <screen><![CDATA[ |
| SELECT xpath_exists('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>', |
| ARRAY[ARRAY['my', 'http://example.com']]); |
| |
| xpath_exists |
| -------------- |
| t |
| (1 row) |
| ]]></screen> |
| </para> |
| </sect3> |
| |
| <sect3 id="functions-xml-processing-xmltable"> |
| <title><literal>xmltable</literal></title> |
| |
| <indexterm> |
| <primary>xmltable</primary> |
| </indexterm> |
| |
| <indexterm zone="functions-xml-processing-xmltable"> |
| <primary>table function</primary> |
| <secondary>XMLTABLE</secondary> |
| </indexterm> |
| |
| <synopsis> |
| <function>XMLTABLE</function> ( |
| <optional> <literal>XMLNAMESPACES</literal> ( <replaceable>namespace_uri</replaceable> <literal>AS</literal> <replaceable>namespace_name</replaceable> <optional>, ...</optional> ), </optional> |
| <replaceable>row_expression</replaceable> <literal>PASSING</literal> <optional><literal>BY</literal> {<literal>REF</literal>|<literal>VALUE</literal>}</optional> <replaceable>document_expression</replaceable> <optional><literal>BY</literal> {<literal>REF</literal>|<literal>VALUE</literal>}</optional> |
| <literal>COLUMNS</literal> <replaceable>name</replaceable> { <replaceable>type</replaceable> <optional><literal>PATH</literal> <replaceable>column_expression</replaceable></optional> <optional><literal>DEFAULT</literal> <replaceable>default_expression</replaceable></optional> <optional><literal>NOT NULL</literal> | <literal>NULL</literal></optional> |
| | <literal>FOR ORDINALITY</literal> } |
| <optional>, ...</optional> |
| ) <returnvalue>setof record</returnvalue> |
| </synopsis> |
| |
| <para> |
| The <function>xmltable</function> expression produces a table based |
| on an XML value, an XPath filter to extract rows, and a |
| set of column definitions. |
| Although it syntactically resembles a function, it can only appear |
| as a table in a query's <literal>FROM</literal> clause. |
| </para> |
| |
| <para> |
| The optional <literal>XMLNAMESPACES</literal> clause gives a |
| comma-separated list of namespace definitions, where |
| each <replaceable>namespace_uri</replaceable> is a <type>text</type> |
| expression and each <replaceable>namespace_name</replaceable> is a simple |
| identifier. It specifies the XML namespaces used in the document and |
| their aliases. A default namespace specification is not currently |
| supported. |
| </para> |
| |
| <para> |
| The required <replaceable>row_expression</replaceable> argument is an |
| XPath 1.0 expression (given as <type>text</type>) that is evaluated, |
| passing the XML value <replaceable>document_expression</replaceable> as |
| its context item, to obtain a set of XML nodes. These nodes are what |
| <function>xmltable</function> transforms into output rows. No rows |
| will be produced if the <replaceable>document_expression</replaceable> |
| is null, nor if the <replaceable>row_expression</replaceable> produces |
| an empty node-set or any value other than a node-set. |
| </para> |
| |
| <para> |
| <replaceable>document_expression</replaceable> provides the context |
| item for the <replaceable>row_expression</replaceable>. It must be a |
| well-formed XML document; fragments/forests are not accepted. |
| The <literal>BY REF</literal> and <literal>BY VALUE</literal> clauses |
| are accepted but ignored, as discussed in |
| <xref linkend="functions-xml-limits-postgresql"/>. |
| </para> |
| |
| <para> |
| In the SQL standard, the <function>xmltable</function> function |
| evaluates expressions in the XML Query language, |
| but <productname>PostgreSQL</productname> allows only XPath 1.0 |
| expressions, as discussed in |
| <xref linkend="functions-xml-limits-xpath1"/>. |
| </para> |
| |
| <para> |
| The required <literal>COLUMNS</literal> clause specifies the |
| column(s) that will be produced in the output table. |
| See the syntax summary above for the format. |
| A name is required for each column, as is a data type |
| (unless <literal>FOR ORDINALITY</literal> is specified, in which case |
| type <type>integer</type> is implicit). The path, default and |
| nullability clauses are optional. |
| </para> |
| |
| <para> |
| A column marked <literal>FOR ORDINALITY</literal> will be populated |
| with row numbers, starting with 1, in the order of nodes retrieved from |
| the <replaceable>row_expression</replaceable>'s result node-set. |
| At most one column may be marked <literal>FOR ORDINALITY</literal>. |
| </para> |
| |
| <note> |
| <para> |
| XPath 1.0 does not specify an order for nodes in a node-set, so code |
| that relies on a particular order of the results will be |
| implementation-dependent. Details can be found in |
| <xref linkend="xml-xpath-1-specifics"/>. |
| </para> |
| </note> |
| |
| <para> |
| The <replaceable>column_expression</replaceable> for a column is an |
| XPath 1.0 expression that is evaluated for each row, with the current |
| node from the <replaceable>row_expression</replaceable> result as its |
| context item, to find the value of the column. If |
| no <replaceable>column_expression</replaceable> is given, then the |
| column name is used as an implicit path. |
| </para> |
| |
| <para> |
| If a column's XPath expression returns a non-XML value (which is limited |
| to string, boolean, or double in XPath 1.0) and the column has a |
| PostgreSQL type other than <type>xml</type>, the column will be set |
| as if by assigning the value's string representation to the PostgreSQL |
| type. (If the value is a boolean, its string representation is taken |
| to be <literal>1</literal> or <literal>0</literal> if the output |
| column's type category is numeric, otherwise <literal>true</literal> or |
| <literal>false</literal>.) |
| </para> |
| |
| <para> |
| If a column's XPath expression returns a non-empty set of XML nodes |
| and the column's PostgreSQL type is <type>xml</type>, the column will |
| be assigned the expression result exactly, if it is of document or |
| content form. |
| <footnote> |
| <para> |
| A result containing more than one element node at the top level, or |
| non-whitespace text outside of an element, is an example of content form. |
| An XPath result can be of neither form, for example if it returns an |
| attribute node selected from the element that contains it. Such a result |
| will be put into content form with each such disallowed node replaced by |
| its string value, as defined for the XPath 1.0 |
| <function>string</function> function. |
| </para> |
| </footnote> |
| </para> |
| |
| <para> |
| A non-XML result assigned to an <type>xml</type> output column produces |
| content, a single text node with the string value of the result. |
| An XML result assigned to a column of any other type may not have more than |
| one node, or an error is raised. If there is exactly one node, the column |
| will be set as if by assigning the node's string |
| value (as defined for the XPath 1.0 <function>string</function> function) |
| to the PostgreSQL type. |
| </para> |
| |
| <para> |
| The string value of an XML element is the concatenation, in document order, |
| of all text nodes contained in that element and its descendants. The string |
| value of an element with no descendant text nodes is an |
| empty string (not <literal>NULL</literal>). |
| Any <literal>xsi:nil</literal> attributes are ignored. |
| Note that the whitespace-only <literal>text()</literal> node between two non-text |
| elements is preserved, and that leading whitespace on a <literal>text()</literal> |
| node is not flattened. |
| The XPath 1.0 <function>string</function> function may be consulted for the |
| rules defining the string value of other XML node types and non-XML values. |
| </para> |
| |
| <para> |
| The conversion rules presented here are not exactly those of the SQL |
| standard, as discussed in <xref linkend="functions-xml-limits-casts"/>. |
| </para> |
| |
| <para> |
| If the path expression returns an empty node-set |
| (typically, when it does not match) |
| for a given row, the column will be set to <literal>NULL</literal>, unless |
| a <replaceable>default_expression</replaceable> is specified; then the |
| value resulting from evaluating that expression is used. |
| </para> |
| |
| <para> |
| A <replaceable>default_expression</replaceable>, rather than being |
| evaluated immediately when <function>xmltable</function> is called, |
| is evaluated each time a default is needed for the column. |
| If the expression qualifies as stable or immutable, the repeat |
| evaluation may be skipped. |
| This means that you can usefully use volatile functions like |
| <function>nextval</function> in |
| <replaceable>default_expression</replaceable>. |
| </para> |
| |
| <para> |
| Columns may be marked <literal>NOT NULL</literal>. If the |
| <replaceable>column_expression</replaceable> for a <literal>NOT |
| NULL</literal> column does not match anything and there is |
| no <literal>DEFAULT</literal> or |
| the <replaceable>default_expression</replaceable> also evaluates to null, |
| an error is reported. |
| </para> |
| |
| <para> |
| Examples: |
| <screen><![CDATA[ |
| CREATE TABLE xmldata AS SELECT |
| xml $$ |
| <ROWS> |
| <ROW id="1"> |
| <COUNTRY_ID>AU</COUNTRY_ID> |
| <COUNTRY_NAME>Australia</COUNTRY_NAME> |
| </ROW> |
| <ROW id="5"> |
| <COUNTRY_ID>JP</COUNTRY_ID> |
| <COUNTRY_NAME>Japan</COUNTRY_NAME> |
| <PREMIER_NAME>Shinzo Abe</PREMIER_NAME> |
| <SIZE unit="sq_mi">145935</SIZE> |
| </ROW> |
| <ROW id="6"> |
| <COUNTRY_ID>SG</COUNTRY_ID> |
| <COUNTRY_NAME>Singapore</COUNTRY_NAME> |
| <SIZE unit="sq_km">697</SIZE> |
| </ROW> |
| </ROWS> |
| $$ AS data; |
| |
| SELECT xmltable.* |
| FROM xmldata, |
| XMLTABLE('//ROWS/ROW' |
| PASSING data |
| COLUMNS id int PATH '@id', |
| ordinality FOR ORDINALITY, |
| "COUNTRY_NAME" text, |
| country_id text PATH 'COUNTRY_ID', |
| size_sq_km float PATH 'SIZE[@unit = "sq_km"]', |
| size_other text PATH |
| 'concat(SIZE[@unit!="sq_km"], " ", SIZE[@unit!="sq_km"]/@unit)', |
| premier_name text PATH 'PREMIER_NAME' DEFAULT 'not specified'); |
| |
| id | ordinality | COUNTRY_NAME | country_id | size_sq_km | size_other | premier_name |
| ----+------------+--------------+------------+------------+--------------+--------------- |
| 1 | 1 | Australia | AU | | | not specified |
| 5 | 2 | Japan | JP | | 145935 sq_mi | Shinzo Abe |
| 6 | 3 | Singapore | SG | 697 | | not specified |
| ]]></screen> |
| |
| The following example shows concatenation of multiple text() nodes, |
| usage of the column name as XPath filter, and the treatment of whitespace, |
| XML comments and processing instructions: |
| |
| <screen><![CDATA[ |
| CREATE TABLE xmlelements AS SELECT |
| xml $$ |
| <root> |
| <element> Hello<!-- xyxxz -->2a2<?aaaaa?> <!--x--> bbb<x>xxx</x>CC </element> |
| </root> |
| $$ AS data; |
| |
| SELECT xmltable.* |
| FROM xmlelements, XMLTABLE('/root' PASSING data COLUMNS element text); |
| element |
| ------------------------- |
| Hello2a2 bbbxxxCC |
| ]]></screen> |
| </para> |
| |
| <para> |
| The following example illustrates how |
| the <literal>XMLNAMESPACES</literal> clause can be used to specify |
| a list of namespaces |
| used in the XML document as well as in the XPath expressions: |
| |
| <screen><![CDATA[ |
| WITH xmldata(data) AS (VALUES (' |
| <example xmlns="http://example.com/myns" xmlns:B="http://example.com/b"> |
| <item foo="1" B:bar="2"/> |
| <item foo="3" B:bar="4"/> |
| <item foo="4" B:bar="5"/> |
| </example>'::xml) |
| ) |
| SELECT xmltable.* |
| FROM XMLTABLE(XMLNAMESPACES('http://example.com/myns' AS x, |
| 'http://example.com/b' AS "B"), |
| '/x:example/x:item' |
| PASSING (SELECT data FROM xmldata) |
| COLUMNS foo int PATH '@foo', |
| bar int PATH '@B:bar'); |
| foo | bar |
| -----+----- |
| 1 | 2 |
| 3 | 4 |
| 4 | 5 |
| (3 rows) |
| ]]></screen> |
| </para> |
| </sect3> |
| </sect2> |
| |
| <sect2 id="functions-xml-mapping"> |
| <title>Mapping Tables to XML</title> |
| |
| <indexterm zone="functions-xml-mapping"> |
| <primary>XML export</primary> |
| </indexterm> |
| |
| <para> |
| The following functions map the contents of relational tables to |
| XML values. They can be thought of as XML export functionality: |
| <synopsis> |
| <function>table_to_xml</function> ( <parameter>table</parameter> <type>regclass</type>, <parameter>nulls</parameter> <type>boolean</type>, |
| <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue> |
| <function>query_to_xml</function> ( <parameter>query</parameter> <type>text</type>, <parameter>nulls</parameter> <type>boolean</type>, |
| <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue> |
| <function>cursor_to_xml</function> ( <parameter>cursor</parameter> <type>refcursor</type>, <parameter>count</parameter> <type>integer</type>, <parameter>nulls</parameter> <type>boolean</type>, |
| <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue> |
| </synopsis> |
| </para> |
| |
| <para> |
| <function>table_to_xml</function> maps the content of the named |
| table, passed as parameter <parameter>table</parameter>. The |
| <type>regclass</type> type accepts strings identifying tables using the |
| usual notation, including optional schema qualification and |
| double quotes (see <xref linkend="datatype-oid"/> for details). |
| <function>query_to_xml</function> executes the |
| query whose text is passed as parameter |
| <parameter>query</parameter> and maps the result set. |
| <function>cursor_to_xml</function> fetches the indicated number of |
| rows from the cursor specified by the parameter |
| <parameter>cursor</parameter>. This variant is recommended if |
| large tables have to be mapped, because the result value is built |
| up in memory by each function. |
| </para> |
| |
| <para> |
| If <parameter>tableforest</parameter> is false, then the resulting |
| XML document looks like this: |
| <screen><![CDATA[ |
| <tablename> |
| <row> |
| <columnname1>data</columnname1> |
| <columnname2>data</columnname2> |
| </row> |
| |
| <row> |
| ... |
| </row> |
| |
| ... |
| </tablename> |
| ]]></screen> |
| |
| If <parameter>tableforest</parameter> is true, the result is an |
| XML content fragment that looks like this: |
| <screen><![CDATA[ |
| <tablename> |
| <columnname1>data</columnname1> |
| <columnname2>data</columnname2> |
| </tablename> |
| |
| <tablename> |
| ... |
| </tablename> |
| |
| ... |
| ]]></screen> |
| |
| If no table name is available, that is, when mapping a query or a |
| cursor, the string <literal>table</literal> is used in the first |
| format, <literal>row</literal> in the second format. |
| </para> |
| |
| <para> |
| The choice between these formats is up to the user. The first |
| format is a proper XML document, which will be important in many |
| applications. The second format tends to be more useful in the |
| <function>cursor_to_xml</function> function if the result values are to be |
| reassembled into one document later on. The functions for |
| producing XML content discussed above, in particular |
| <function>xmlelement</function>, can be used to alter the results |
| to taste. |
| </para> |
| |
| <para> |
| The data values are mapped in the same way as described for the |
| function <function>xmlelement</function> above. |
| </para> |
| |
| <para> |
| The parameter <parameter>nulls</parameter> determines whether null |
| values should be included in the output. If true, null values in |
| columns are represented as: |
| <screen><![CDATA[ |
| <columnname xsi:nil="true"/> |
| ]]></screen> |
| where <literal>xsi</literal> is the XML namespace prefix for XML |
| Schema Instance. An appropriate namespace declaration will be |
| added to the result value. If false, columns containing null |
| values are simply omitted from the output. |
| </para> |
| |
| <para> |
| The parameter <parameter>targetns</parameter> specifies the |
| desired XML namespace of the result. If no particular namespace |
| is wanted, an empty string should be passed. |
| </para> |
| |
| <para> |
| The following functions return XML Schema documents describing the |
| mappings performed by the corresponding functions above: |
| <synopsis> |
| <function>table_to_xmlschema</function> ( <parameter>table</parameter> <type>regclass</type>, <parameter>nulls</parameter> <type>boolean</type>, |
| <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue> |
| <function>query_to_xmlschema</function> ( <parameter>query</parameter> <type>text</type>, <parameter>nulls</parameter> <type>boolean</type>, |
| <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue> |
| <function>cursor_to_xmlschema</function> ( <parameter>cursor</parameter> <type>refcursor</type>, <parameter>nulls</parameter> <type>boolean</type>, |
| <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue> |
| </synopsis> |
| It is essential that the same parameters are passed in order to |
| obtain matching XML data mappings and XML Schema documents. |
| </para> |
| |
| <para> |
| The following functions produce XML data mappings and the |
| corresponding XML Schema in one document (or forest), linked |
| together. They can be useful where self-contained and |
| self-describing results are wanted: |
| <synopsis> |
| <function>table_to_xml_and_xmlschema</function> ( <parameter>table</parameter> <type>regclass</type>, <parameter>nulls</parameter> <type>boolean</type>, |
| <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue> |
| <function>query_to_xml_and_xmlschema</function> ( <parameter>query</parameter> <type>text</type>, <parameter>nulls</parameter> <type>boolean</type>, |
| <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue> |
| </synopsis> |
| </para> |
| |
| <para> |
| In addition, the following functions are available to produce |
| analogous mappings of entire schemas or the entire current |
| database: |
| <synopsis> |
| <function>schema_to_xml</function> ( <parameter>schema</parameter> <type>name</type>, <parameter>nulls</parameter> <type>boolean</type>, |
| <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue> |
| <function>schema_to_xmlschema</function> ( <parameter>schema</parameter> <type>name</type>, <parameter>nulls</parameter> <type>boolean</type>, |
| <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue> |
| <function>schema_to_xml_and_xmlschema</function> ( <parameter>schema</parameter> <type>name</type>, <parameter>nulls</parameter> <type>boolean</type>, |
| <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue> |
| |
| <function>database_to_xml</function> ( <parameter>nulls</parameter> <type>boolean</type>, |
| <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue> |
| <function>database_to_xmlschema</function> ( <parameter>nulls</parameter> <type>boolean</type>, |
| <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue> |
| <function>database_to_xml_and_xmlschema</function> ( <parameter>nulls</parameter> <type>boolean</type>, |
| <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue> |
| </synopsis> |
| |
| These functions ignore tables that are not readable by the current user. |
| The database-wide functions additionally ignore schemas that the current |
| user does not have <literal>USAGE</literal> (lookup) privilege for. |
| </para> |
| |
| <para> |
| Note that these potentially produce a lot of data, which needs to |
| be built up in memory. When requesting content mappings of large |
| schemas or databases, it might be worthwhile to consider mapping the |
| tables separately instead, possibly even through a cursor. |
| </para> |
| |
| <para> |
| The result of a schema content mapping looks like this: |
| |
| <screen><![CDATA[ |
| <schemaname> |
| |
| table1-mapping |
| |
| table2-mapping |
| |
| ... |
| |
| </schemaname>]]></screen> |
| |
| where the format of a table mapping depends on the |
| <parameter>tableforest</parameter> parameter as explained above. |
| </para> |
| |
| <para> |
| The result of a database content mapping looks like this: |
| |
| <screen><![CDATA[ |
| <dbname> |
| |
| <schema1name> |
| ... |
| </schema1name> |
| |
| <schema2name> |
| ... |
| </schema2name> |
| |
| ... |
| |
| </dbname>]]></screen> |
| |
| where the schema mapping is as above. |
| </para> |
| |
| <para> |
| As an example of using the output produced by these functions, |
| <xref linkend="xslt-xml-html"/> shows an XSLT stylesheet that |
| converts the output of |
| <function>table_to_xml_and_xmlschema</function> to an HTML |
| document containing a tabular rendition of the table data. In a |
| similar manner, the results from these functions can be |
| converted into other XML-based formats. |
| </para> |
| |
| <example id="xslt-xml-html"> |
| <title>XSLT Stylesheet for Converting SQL/XML Output to HTML</title> |
| <programlisting><![CDATA[ |
| <?xml version="1.0"?> |
| <xsl:stylesheet version="1.0" |
| xmlns:xsl="http://www.w3.org/1999/XSL/Transform" |
| xmlns:xsd="http://www.w3.org/2001/XMLSchema" |
| xmlns="http://www.w3.org/1999/xhtml" |
| > |
| |
| <xsl:output method="xml" |
| doctype-system="http://www.w3.org/TR/xhtml1/DTD/xhtml1-strict.dtd" |
| doctype-public="-//W3C/DTD XHTML 1.0 Strict//EN" |
| indent="yes"/> |
| |
| <xsl:template match="/*"> |
| <xsl:variable name="schema" select="//xsd:schema"/> |
| <xsl:variable name="tabletypename" |
| select="$schema/xsd:element[@name=name(current())]/@type"/> |
| <xsl:variable name="rowtypename" |
| select="$schema/xsd:complexType[@name=$tabletypename]/xsd:sequence/xsd:element[@name='row']/@type"/> |
| |
| <html> |
| <head> |
| <title><xsl:value-of select="name(current())"/></title> |
| </head> |
| <body> |
| <table> |
| <tr> |
| <xsl:for-each select="$schema/xsd:complexType[@name=$rowtypename]/xsd:sequence/xsd:element/@name"> |
| <th><xsl:value-of select="."/></th> |
| </xsl:for-each> |
| </tr> |
| |
| <xsl:for-each select="row"> |
| <tr> |
| <xsl:for-each select="*"> |
| <td><xsl:value-of select="."/></td> |
| </xsl:for-each> |
| </tr> |
| </xsl:for-each> |
| </table> |
| </body> |
| </html> |
| </xsl:template> |
| |
| </xsl:stylesheet> |
| ]]></programlisting> |
| </example> |
| </sect2> |
| </sect1> |
| |
| <sect1 id="functions-json"> |
| <title>JSON Functions and Operators</title> |
| |
| <indexterm zone="functions-json"> |
| <primary>JSON</primary> |
| <secondary>functions and operators</secondary> |
| </indexterm> |
| |
| <para> |
| This section describes: |
| |
| <itemizedlist> |
| <listitem> |
| <para> |
| functions and operators for processing and creating JSON data |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| the SQL/JSON path language |
| </para> |
| </listitem> |
| </itemizedlist> |
| </para> |
| |
| <para> |
| To learn more about the SQL/JSON standard, see |
| <xref linkend="sqltr-19075-6"/>. For details on JSON types |
| supported in <productname>PostgreSQL</productname>, |
| see <xref linkend="datatype-json"/>. |
| </para> |
| |
| <sect2 id="functions-json-processing"> |
| <title>Processing and Creating JSON Data</title> |
| |
| <para> |
| <xref linkend="functions-json-op-table"/> shows the operators that |
| are available for use with JSON data types (see <xref |
| linkend="datatype-json"/>). |
| In addition, the usual comparison operators shown in <xref |
| linkend="functions-comparison-op-table"/> are available for |
| <type>jsonb</type>, though not for <type>json</type>. The comparison |
| operators follow the ordering rules for B-tree operations outlined in |
| <xref linkend="json-indexing"/>. |
| </para> |
| |
| <table id="functions-json-op-table"> |
| <title><type>json</type> and <type>jsonb</type> Operators</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Operator |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>json</type> <literal>-></literal> <type>integer</type> |
| <returnvalue>json</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <type>jsonb</type> <literal>-></literal> <type>integer</type> |
| <returnvalue>jsonb</returnvalue> |
| </para> |
| <para> |
| Extracts <parameter>n</parameter>'th element of JSON array |
| (array elements are indexed from zero, but negative integers count |
| from the end). |
| </para> |
| <para> |
| <literal>'[{"a":"foo"},{"b":"bar"},{"c":"baz"}]'::json -> 2</literal> |
| <returnvalue>{"c":"baz"}</returnvalue> |
| </para> |
| <para> |
| <literal>'[{"a":"foo"},{"b":"bar"},{"c":"baz"}]'::json -> -3</literal> |
| <returnvalue>{"a":"foo"}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>json</type> <literal>-></literal> <type>text</type> |
| <returnvalue>json</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <type>jsonb</type> <literal>-></literal> <type>text</type> |
| <returnvalue>jsonb</returnvalue> |
| </para> |
| <para> |
| Extracts JSON object field with the given key. |
| </para> |
| <para> |
| <literal>'{"a": {"b":"foo"}}'::json -> 'a'</literal> |
| <returnvalue>{"b":"foo"}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>json</type> <literal>->></literal> <type>integer</type> |
| <returnvalue>text</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <type>jsonb</type> <literal>->></literal> <type>integer</type> |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Extracts <parameter>n</parameter>'th element of JSON array, |
| as <type>text</type>. |
| </para> |
| <para> |
| <literal>'[1,2,3]'::json ->> 2</literal> |
| <returnvalue>3</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>json</type> <literal>->></literal> <type>text</type> |
| <returnvalue>text</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <type>jsonb</type> <literal>->></literal> <type>text</type> |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Extracts JSON object field with the given key, as <type>text</type>. |
| </para> |
| <para> |
| <literal>'{"a":1,"b":2}'::json ->> 'b'</literal> |
| <returnvalue>2</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>json</type> <literal>#></literal> <type>text[]</type> |
| <returnvalue>json</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <type>jsonb</type> <literal>#></literal> <type>text[]</type> |
| <returnvalue>jsonb</returnvalue> |
| </para> |
| <para> |
| Extracts JSON sub-object at the specified path, where path elements |
| can be either field keys or array indexes. |
| </para> |
| <para> |
| <literal>'{"a": {"b": ["foo","bar"]}}'::json #> '{a,b,1}'</literal> |
| <returnvalue>"bar"</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>json</type> <literal>#>></literal> <type>text[]</type> |
| <returnvalue>text</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <type>jsonb</type> <literal>#>></literal> <type>text[]</type> |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Extracts JSON sub-object at the specified path as <type>text</type>. |
| </para> |
| <para> |
| <literal>'{"a": {"b": ["foo","bar"]}}'::json #>> '{a,b,1}'</literal> |
| <returnvalue>bar</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <note> |
| <para> |
| The field/element/path extraction operators return NULL, rather than |
| failing, if the JSON input does not have the right structure to match |
| the request; for example if no such key or array element exists. |
| </para> |
| </note> |
| |
| <para> |
| Some further operators exist only for <type>jsonb</type>, as shown |
| in <xref linkend="functions-jsonb-op-table"/>. |
| <xref linkend="json-indexing"/> |
| describes how these operators can be used to effectively search indexed |
| <type>jsonb</type> data. |
| </para> |
| |
| <table id="functions-jsonb-op-table"> |
| <title>Additional <type>jsonb</type> Operators</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Operator |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>jsonb</type> <literal>@></literal> <type>jsonb</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does the first JSON value contain the second? |
| (See <xref linkend="json-containment"/> for details about containment.) |
| </para> |
| <para> |
| <literal>'{"a":1, "b":2}'::jsonb @> '{"b":2}'::jsonb</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>jsonb</type> <literal><@</literal> <type>jsonb</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the first JSON value contained in the second? |
| </para> |
| <para> |
| <literal>'{"b":2}'::jsonb <@ '{"a":1, "b":2}'::jsonb</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>jsonb</type> <literal>?</literal> <type>text</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does the text string exist as a top-level key or array element within |
| the JSON value? |
| </para> |
| <para> |
| <literal>'{"a":1, "b":2}'::jsonb ? 'b'</literal> |
| <returnvalue>t</returnvalue> |
| </para> |
| <para> |
| <literal>'["a", "b", "c"]'::jsonb ? 'b'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>jsonb</type> <literal>?|</literal> <type>text[]</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Do any of the strings in the text array exist as top-level keys or |
| array elements? |
| </para> |
| <para> |
| <literal>'{"a":1, "b":2, "c":3}'::jsonb ?| array['b', 'd']</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>jsonb</type> <literal>?&</literal> <type>text[]</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Do all of the strings in the text array exist as top-level keys or |
| array elements? |
| </para> |
| <para> |
| <literal>'["a", "b", "c"]'::jsonb ?& array['a', 'b']</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>jsonb</type> <literal>||</literal> <type>jsonb</type> |
| <returnvalue>jsonb</returnvalue> |
| </para> |
| <para> |
| Concatenates two <type>jsonb</type> values. |
| Concatenating two arrays generates an array containing all the |
| elements of each input. Concatenating two objects generates an |
| object containing the union of their |
| keys, taking the second object's value when there are duplicate keys. |
| All other cases are treated by converting a non-array input into a |
| single-element array, and then proceeding as for two arrays. |
| Does not operate recursively: only the top-level array or object |
| structure is merged. |
| </para> |
| <para> |
| <literal>'["a", "b"]'::jsonb || '["a", "d"]'::jsonb</literal> |
| <returnvalue>["a", "b", "a", "d"]</returnvalue> |
| </para> |
| <para> |
| <literal>'{"a": "b"}'::jsonb || '{"c": "d"}'::jsonb</literal> |
| <returnvalue>{"a": "b", "c": "d"}</returnvalue> |
| </para> |
| <para> |
| <literal>'[1, 2]'::jsonb || '3'::jsonb</literal> |
| <returnvalue>[1, 2, 3]</returnvalue> |
| </para> |
| <para> |
| <literal>'{"a": "b"}'::jsonb || '42'::jsonb</literal> |
| <returnvalue>[{"a": "b"}, 42]</returnvalue> |
| </para> |
| <para> |
| To append an array to another array as a single entry, wrap it |
| in an additional layer of array, for example: |
| </para> |
| <para> |
| <literal>'[1, 2]'::jsonb || jsonb_build_array('[3, 4]'::jsonb)</literal> |
| <returnvalue>[1, 2, [3, 4]]</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>jsonb</type> <literal>-</literal> <type>text</type> |
| <returnvalue>jsonb</returnvalue> |
| </para> |
| <para> |
| Deletes a key (and its value) from a JSON object, or matching string |
| value(s) from a JSON array. |
| </para> |
| <para> |
| <literal>'{"a": "b", "c": "d"}'::jsonb - 'a'</literal> |
| <returnvalue>{"c": "d"}</returnvalue> |
| </para> |
| <para> |
| <literal>'["a", "b", "c", "b"]'::jsonb - 'b'</literal> |
| <returnvalue>["a", "c"]</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>jsonb</type> <literal>-</literal> <type>text[]</type> |
| <returnvalue>jsonb</returnvalue> |
| </para> |
| <para> |
| Deletes all matching keys or array elements from the left operand. |
| </para> |
| <para> |
| <literal>'{"a": "b", "c": "d"}'::jsonb - '{a,c}'::text[]</literal> |
| <returnvalue>{}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>jsonb</type> <literal>-</literal> <type>integer</type> |
| <returnvalue>jsonb</returnvalue> |
| </para> |
| <para> |
| Deletes the array element with specified index (negative |
| integers count from the end). Throws an error if JSON value |
| is not an array. |
| </para> |
| <para> |
| <literal>'["a", "b"]'::jsonb - 1 </literal> |
| <returnvalue>["a"]</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>jsonb</type> <literal>#-</literal> <type>text[]</type> |
| <returnvalue>jsonb</returnvalue> |
| </para> |
| <para> |
| Deletes the field or array element at the specified path, where path |
| elements can be either field keys or array indexes. |
| </para> |
| <para> |
| <literal>'["a", {"b":1}]'::jsonb #- '{1,b}'</literal> |
| <returnvalue>["a", {}]</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>jsonb</type> <literal>@?</literal> <type>jsonpath</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does JSON path return any item for the specified JSON value? |
| </para> |
| <para> |
| <literal>'{"a":[1,2,3,4,5]}'::jsonb @? '$.a[*] ? (@ > 2)'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>jsonb</type> <literal>@@</literal> <type>jsonpath</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Returns the result of a JSON path predicate check for the |
| specified JSON value. Only the first item of the result is taken into |
| account. If the result is not Boolean, then <literal>NULL</literal> |
| is returned. |
| </para> |
| <para> |
| <literal>'{"a":[1,2,3,4,5]}'::jsonb @@ '$.a[*] > 2'</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <note> |
| <para> |
| The <type>jsonpath</type> operators <literal>@?</literal> |
| and <literal>@@</literal> suppress the following errors: missing object |
| field or array element, unexpected JSON item type, datetime and numeric |
| errors. The <type>jsonpath</type>-related functions described below can |
| also be told to suppress these types of errors. This behavior might be |
| helpful when searching JSON document collections of varying structure. |
| </para> |
| </note> |
| |
| <para> |
| <xref linkend="functions-json-creation-table"/> shows the functions that are |
| available for constructing <type>json</type> and <type>jsonb</type> values. |
| </para> |
| |
| <table id="functions-json-creation-table"> |
| <title>JSON Creation Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>to_json</primary> |
| </indexterm> |
| <function>to_json</function> ( <type>anyelement</type> ) |
| <returnvalue>json</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <indexterm> |
| <primary>to_jsonb</primary> |
| </indexterm> |
| <function>to_jsonb</function> ( <type>anyelement</type> ) |
| <returnvalue>jsonb</returnvalue> |
| </para> |
| <para> |
| Converts any SQL value to <type>json</type> or <type>jsonb</type>. |
| Arrays and composites are converted recursively to arrays and |
| objects (multidimensional arrays become arrays of arrays in JSON). |
| Otherwise, if there is a cast from the SQL data type |
| to <type>json</type>, the cast function will be used to perform the |
| conversion;<footnote> |
| <para> |
| For example, the <xref linkend="hstore"/> extension has a cast |
| from <type>hstore</type> to <type>json</type>, so that |
| <type>hstore</type> values converted via the JSON creation functions |
| will be represented as JSON objects, not as primitive string values. |
| </para> |
| </footnote> |
| otherwise, a scalar JSON value is produced. For any scalar other than |
| a number, a Boolean, or a null value, the text representation will be |
| used, with escaping as necessary to make it a valid JSON string value. |
| </para> |
| <para> |
| <literal>to_json('Fred said "Hi."'::text)</literal> |
| <returnvalue>"Fred said \"Hi.\""</returnvalue> |
| </para> |
| <para> |
| <literal>to_jsonb(row(42, 'Fred said "Hi."'::text))</literal> |
| <returnvalue>{"f1": 42, "f2": "Fred said \"Hi.\""}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>array_to_json</primary> |
| </indexterm> |
| <function>array_to_json</function> ( <type>anyarray</type> <optional>, <type>boolean</type> </optional> ) |
| <returnvalue>json</returnvalue> |
| </para> |
| <para> |
| Converts an SQL array to a JSON array. The behavior is the same |
| as <function>to_json</function> except that line feeds will be added |
| between top-level array elements if the optional boolean parameter is |
| true. |
| </para> |
| <para> |
| <literal>array_to_json('{{1,5},{99,100}}'::int[])</literal> |
| <returnvalue>[[1,5],[99,100]]</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>row_to_json</primary> |
| </indexterm> |
| <function>row_to_json</function> ( <type>record</type> <optional>, <type>boolean</type> </optional> ) |
| <returnvalue>json</returnvalue> |
| </para> |
| <para> |
| Converts an SQL composite value to a JSON object. The behavior is the |
| same as <function>to_json</function> except that line feeds will be |
| added between top-level elements if the optional boolean parameter is |
| true. |
| </para> |
| <para> |
| <literal>row_to_json(row(1,'foo'))</literal> |
| <returnvalue>{"f1":1,"f2":"foo"}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>json_build_array</primary> |
| </indexterm> |
| <function>json_build_array</function> ( <literal>VARIADIC</literal> <type>"any"</type> ) |
| <returnvalue>json</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_build_array</primary> |
| </indexterm> |
| <function>jsonb_build_array</function> ( <literal>VARIADIC</literal> <type>"any"</type> ) |
| <returnvalue>jsonb</returnvalue> |
| </para> |
| <para> |
| Builds a possibly-heterogeneously-typed JSON array out of a variadic |
| argument list. Each argument is converted as |
| per <function>to_json</function> or <function>to_jsonb</function>. |
| </para> |
| <para> |
| <literal>json_build_array(1, 2, 'foo', 4, 5)</literal> |
| <returnvalue>[1, 2, "foo", 4, 5]</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>json_build_object</primary> |
| </indexterm> |
| <function>json_build_object</function> ( <literal>VARIADIC</literal> <type>"any"</type> ) |
| <returnvalue>json</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_build_object</primary> |
| </indexterm> |
| <function>jsonb_build_object</function> ( <literal>VARIADIC</literal> <type>"any"</type> ) |
| <returnvalue>jsonb</returnvalue> |
| </para> |
| <para> |
| Builds a JSON object out of a variadic argument list. By convention, |
| the argument list consists of alternating keys and values. Key |
| arguments are coerced to text; value arguments are converted as |
| per <function>to_json</function> or <function>to_jsonb</function>. |
| </para> |
| <para> |
| <literal>json_build_object('foo', 1, 2, row(3,'bar'))</literal> |
| <returnvalue>{"foo" : 1, "2" : {"f1":3,"f2":"bar"}}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>json_object</primary> |
| </indexterm> |
| <function>json_object</function> ( <type>text[]</type> ) |
| <returnvalue>json</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_object</primary> |
| </indexterm> |
| <function>jsonb_object</function> ( <type>text[]</type> ) |
| <returnvalue>jsonb</returnvalue> |
| </para> |
| <para> |
| Builds a JSON object out of a text array. The array must have either |
| exactly one dimension with an even number of members, in which case |
| they are taken as alternating key/value pairs, or two dimensions |
| such that each inner array has exactly two elements, which |
| are taken as a key/value pair. All values are converted to JSON |
| strings. |
| </para> |
| <para> |
| <literal>json_object('{a, 1, b, "def", c, 3.5}')</literal> |
| <returnvalue>{"a" : "1", "b" : "def", "c" : "3.5"}</returnvalue> |
| </para> |
| <para><literal>json_object('{{a, 1}, {b, "def"}, {c, 3.5}}')</literal> |
| <returnvalue>{"a" : "1", "b" : "def", "c" : "3.5"}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>json_object</function> ( <parameter>keys</parameter> <type>text[]</type>, <parameter>values</parameter> <type>text[]</type> ) |
| <returnvalue>json</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>jsonb_object</function> ( <parameter>keys</parameter> <type>text[]</type>, <parameter>values</parameter> <type>text[]</type> ) |
| <returnvalue>jsonb</returnvalue> |
| </para> |
| <para> |
| This form of <function>json_object</function> takes keys and values |
| pairwise from separate text arrays. Otherwise it is identical to |
| the one-argument form. |
| </para> |
| <para> |
| <literal>json_object('{a,b}', '{1,2}')</literal> |
| <returnvalue>{"a": "1", "b": "2"}</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| <xref linkend="functions-json-processing-table"/> shows the functions that |
| are available for processing <type>json</type> and <type>jsonb</type> values. |
| </para> |
| |
| <table id="functions-json-processing-table"> |
| <title>JSON Processing Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>json_array_elements</primary> |
| </indexterm> |
| <function>json_array_elements</function> ( <type>json</type> ) |
| <returnvalue>setof json</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_array_elements</primary> |
| </indexterm> |
| <function>jsonb_array_elements</function> ( <type>jsonb</type> ) |
| <returnvalue>setof jsonb</returnvalue> |
| </para> |
| <para> |
| Expands the top-level JSON array into a set of JSON values. |
| </para> |
| <para> |
| <literal>select * from json_array_elements('[1,true, [2,false]]')</literal> |
| <returnvalue></returnvalue> |
| <programlisting> |
| value |
| ----------- |
| 1 |
| true |
| [2,false] |
| </programlisting> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>json_array_elements_text</primary> |
| </indexterm> |
| <function>json_array_elements_text</function> ( <type>json</type> ) |
| <returnvalue>setof text</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_array_elements_text</primary> |
| </indexterm> |
| <function>jsonb_array_elements_text</function> ( <type>jsonb</type> ) |
| <returnvalue>setof text</returnvalue> |
| </para> |
| <para> |
| Expands the top-level JSON array into a set of <type>text</type> values. |
| </para> |
| <para> |
| <literal>select * from json_array_elements_text('["foo", "bar"]')</literal> |
| <returnvalue></returnvalue> |
| <programlisting> |
| value |
| ----------- |
| foo |
| bar |
| </programlisting> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>json_array_length</primary> |
| </indexterm> |
| <function>json_array_length</function> ( <type>json</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_array_length</primary> |
| </indexterm> |
| <function>jsonb_array_length</function> ( <type>jsonb</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns the number of elements in the top-level JSON array. |
| </para> |
| <para> |
| <literal>json_array_length('[1,2,3,{"f1":1,"f2":[5,6]},4]')</literal> |
| <returnvalue>5</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>json_each</primary> |
| </indexterm> |
| <function>json_each</function> ( <type>json</type> ) |
| <returnvalue>setof record</returnvalue> |
| ( <parameter>key</parameter> <type>text</type>, |
| <parameter>value</parameter> <type>json</type> ) |
| </para> |
| <para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_each</primary> |
| </indexterm> |
| <function>jsonb_each</function> ( <type>jsonb</type> ) |
| <returnvalue>setof record</returnvalue> |
| ( <parameter>key</parameter> <type>text</type>, |
| <parameter>value</parameter> <type>jsonb</type> ) |
| </para> |
| <para> |
| Expands the top-level JSON object into a set of key/value pairs. |
| </para> |
| <para> |
| <literal>select * from json_each('{"a":"foo", "b":"bar"}')</literal> |
| <returnvalue></returnvalue> |
| <programlisting> |
| key | value |
| -----+------- |
| a | "foo" |
| b | "bar" |
| </programlisting> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>json_each_text</primary> |
| </indexterm> |
| <function>json_each_text</function> ( <type>json</type> ) |
| <returnvalue>setof record</returnvalue> |
| ( <parameter>key</parameter> <type>text</type>, |
| <parameter>value</parameter> <type>text</type> ) |
| </para> |
| <para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_each_text</primary> |
| </indexterm> |
| <function>jsonb_each_text</function> ( <type>jsonb</type> ) |
| <returnvalue>setof record</returnvalue> |
| ( <parameter>key</parameter> <type>text</type>, |
| <parameter>value</parameter> <type>text</type> ) |
| </para> |
| <para> |
| Expands the top-level JSON object into a set of key/value pairs. |
| The returned <parameter>value</parameter>s will be of |
| type <type>text</type>. |
| </para> |
| <para> |
| <literal>select * from json_each_text('{"a":"foo", "b":"bar"}')</literal> |
| <returnvalue></returnvalue> |
| <programlisting> |
| key | value |
| -----+------- |
| a | foo |
| b | bar |
| </programlisting> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>json_extract_path</primary> |
| </indexterm> |
| <function>json_extract_path</function> ( <parameter>from_json</parameter> <type>json</type>, <literal>VARIADIC</literal> <parameter>path_elems</parameter> <type>text[]</type> ) |
| <returnvalue>json</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_extract_path</primary> |
| </indexterm> |
| <function>jsonb_extract_path</function> ( <parameter>from_json</parameter> <type>jsonb</type>, <literal>VARIADIC</literal> <parameter>path_elems</parameter> <type>text[]</type> ) |
| <returnvalue>jsonb</returnvalue> |
| </para> |
| <para> |
| Extracts JSON sub-object at the specified path. |
| (This is functionally equivalent to the <literal>#></literal> |
| operator, but writing the path out as a variadic list can be more |
| convenient in some cases.) |
| </para> |
| <para> |
| <literal>json_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}', 'f4', 'f6')</literal> |
| <returnvalue>"foo"</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>json_extract_path_text</primary> |
| </indexterm> |
| <function>json_extract_path_text</function> ( <parameter>from_json</parameter> <type>json</type>, <literal>VARIADIC</literal> <parameter>path_elems</parameter> <type>text[]</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_extract_path_text</primary> |
| </indexterm> |
| <function>jsonb_extract_path_text</function> ( <parameter>from_json</parameter> <type>jsonb</type>, <literal>VARIADIC</literal> <parameter>path_elems</parameter> <type>text[]</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Extracts JSON sub-object at the specified path as <type>text</type>. |
| (This is functionally equivalent to the <literal>#>></literal> |
| operator.) |
| </para> |
| <para> |
| <literal>json_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}', 'f4', 'f6')</literal> |
| <returnvalue>foo</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>json_object_keys</primary> |
| </indexterm> |
| <function>json_object_keys</function> ( <type>json</type> ) |
| <returnvalue>setof text</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_object_keys</primary> |
| </indexterm> |
| <function>jsonb_object_keys</function> ( <type>jsonb</type> ) |
| <returnvalue>setof text</returnvalue> |
| </para> |
| <para> |
| Returns the set of keys in the top-level JSON object. |
| </para> |
| <para> |
| <literal>select * from json_object_keys('{"f1":"abc","f2":{"f3":"a", "f4":"b"}}')</literal> |
| <returnvalue></returnvalue> |
| <programlisting> |
| json_object_keys |
| ------------------ |
| f1 |
| f2 |
| </programlisting> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>json_populate_record</primary> |
| </indexterm> |
| <function>json_populate_record</function> ( <parameter>base</parameter> <type>anyelement</type>, <parameter>from_json</parameter> <type>json</type> ) |
| <returnvalue>anyelement</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_populate_record</primary> |
| </indexterm> |
| <function>jsonb_populate_record</function> ( <parameter>base</parameter> <type>anyelement</type>, <parameter>from_json</parameter> <type>jsonb</type> ) |
| <returnvalue>anyelement</returnvalue> |
| </para> |
| <para> |
| Expands the top-level JSON object to a row having the composite type |
| of the <parameter>base</parameter> argument. The JSON object |
| is scanned for fields whose names match column names of the output row |
| type, and their values are inserted into those columns of the output. |
| (Fields that do not correspond to any output column name are ignored.) |
| In typical use, the value of <parameter>base</parameter> is just |
| <literal>NULL</literal>, which means that any output columns that do |
| not match any object field will be filled with nulls. However, |
| if <parameter>base</parameter> isn't <literal>NULL</literal> then |
| the values it contains will be used for unmatched columns. |
| </para> |
| <para> |
| To convert a JSON value to the SQL type of an output column, the |
| following rules are applied in sequence: |
| <itemizedlist spacing="compact"> |
| <listitem> |
| <para> |
| A JSON null value is converted to an SQL null in all cases. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| If the output column is of type <type>json</type> |
| or <type>jsonb</type>, the JSON value is just reproduced exactly. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| If the output column is a composite (row) type, and the JSON value |
| is a JSON object, the fields of the object are converted to columns |
| of the output row type by recursive application of these rules. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| Likewise, if the output column is an array type and the JSON value |
| is a JSON array, the elements of the JSON array are converted to |
| elements of the output array by recursive application of these |
| rules. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| Otherwise, if the JSON value is a string, the contents of the |
| string are fed to the input conversion function for the column's |
| data type. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| Otherwise, the ordinary text representation of the JSON value is |
| fed to the input conversion function for the column's data type. |
| </para> |
| </listitem> |
| </itemizedlist> |
| </para> |
| <para> |
| While the example below uses a constant JSON value, typical use would |
| be to reference a <type>json</type> or <type>jsonb</type> column |
| laterally from another table in the query's <literal>FROM</literal> |
| clause. Writing <function>json_populate_record</function> in |
| the <literal>FROM</literal> clause is good practice, since all of the |
| extracted columns are available for use without duplicate function |
| calls. |
| </para> |
| <para> |
| <literal>create type subrowtype as (d int, e text);</literal> |
| <literal>create type myrowtype as (a int, b text[], c subrowtype);</literal> |
| </para> |
| <para> |
| <literal>select * from json_populate_record(null::myrowtype, |
| '{"a": 1, "b": ["2", "a b"], "c": {"d": 4, "e": "a b c"}, "x": "foo"}')</literal> |
| <returnvalue></returnvalue> |
| <programlisting> |
| a | b | c |
| ---+-----------+------------- |
| 1 | {2,"a b"} | (4,"a b c") |
| </programlisting> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>json_populate_recordset</primary> |
| </indexterm> |
| <function>json_populate_recordset</function> ( <parameter>base</parameter> <type>anyelement</type>, <parameter>from_json</parameter> <type>json</type> ) |
| <returnvalue>setof anyelement</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_populate_recordset</primary> |
| </indexterm> |
| <function>jsonb_populate_recordset</function> ( <parameter>base</parameter> <type>anyelement</type>, <parameter>from_json</parameter> <type>jsonb</type> ) |
| <returnvalue>setof anyelement</returnvalue> |
| </para> |
| <para> |
| Expands the top-level JSON array of objects to a set of rows having |
| the composite type of the <parameter>base</parameter> argument. |
| Each element of the JSON array is processed as described above |
| for <function>json[b]_populate_record</function>. |
| </para> |
| <para> |
| <literal>create type twoints as (a int, b int);</literal> |
| </para> |
| <para> |
| <literal>select * from json_populate_recordset(null::twoints, '[{"a":1,"b":2}, {"a":3,"b":4}]')</literal> |
| <returnvalue></returnvalue> |
| <programlisting> |
| a | b |
| ---+--- |
| 1 | 2 |
| 3 | 4 |
| </programlisting> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>json_to_record</primary> |
| </indexterm> |
| <function>json_to_record</function> ( <type>json</type> ) |
| <returnvalue>record</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_to_record</primary> |
| </indexterm> |
| <function>jsonb_to_record</function> ( <type>jsonb</type> ) |
| <returnvalue>record</returnvalue> |
| </para> |
| <para> |
| Expands the top-level JSON object to a row having the composite type |
| defined by an <literal>AS</literal> clause. (As with all functions |
| returning <type>record</type>, the calling query must explicitly |
| define the structure of the record with an <literal>AS</literal> |
| clause.) The output record is filled from fields of the JSON object, |
| in the same way as described above |
| for <function>json[b]_populate_record</function>. Since there is no |
| input record value, unmatched columns are always filled with nulls. |
| </para> |
| <para> |
| <literal>create type myrowtype as (a int, b text);</literal> |
| </para> |
| <para> |
| <literal>select * from json_to_record('{"a":1,"b":[1,2,3],"c":[1,2,3],"e":"bar","r": {"a": 123, "b": "a b c"}}') as x(a int, b text, c int[], d text, r myrowtype)</literal> |
| <returnvalue></returnvalue> |
| <programlisting> |
| a | b | c | d | r |
| ---+---------+---------+---+--------------- |
| 1 | [1,2,3] | {1,2,3} | | (123,"a b c") |
| </programlisting> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>json_to_recordset</primary> |
| </indexterm> |
| <function>json_to_recordset</function> ( <type>json</type> ) |
| <returnvalue>setof record</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_to_recordset</primary> |
| </indexterm> |
| <function>jsonb_to_recordset</function> ( <type>jsonb</type> ) |
| <returnvalue>setof record</returnvalue> |
| </para> |
| <para> |
| Expands the top-level JSON array of objects to a set of rows having |
| the composite type defined by an <literal>AS</literal> clause. (As |
| with all functions returning <type>record</type>, the calling query |
| must explicitly define the structure of the record with |
| an <literal>AS</literal> clause.) Each element of the JSON array is |
| processed as described above |
| for <function>json[b]_populate_record</function>. |
| </para> |
| <para> |
| <literal>select * from json_to_recordset('[{"a":1,"b":"foo"}, {"a":"2","c":"bar"}]') as x(a int, b text)</literal> |
| <returnvalue></returnvalue> |
| <programlisting> |
| a | b |
| ---+----- |
| 1 | foo |
| 2 | |
| </programlisting> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_set</primary> |
| </indexterm> |
| <function>jsonb_set</function> ( <parameter>target</parameter> <type>jsonb</type>, <parameter>path</parameter> <type>text[]</type>, <parameter>new_value</parameter> <type>jsonb</type> <optional>, <parameter>create_if_missing</parameter> <type>boolean</type> </optional> ) |
| <returnvalue>jsonb</returnvalue> |
| </para> |
| <para> |
| Returns <parameter>target</parameter> |
| with the item designated by <parameter>path</parameter> |
| replaced by <parameter>new_value</parameter>, or with |
| <parameter>new_value</parameter> added if |
| <parameter>create_if_missing</parameter> is true (which is the |
| default) and the item designated by <parameter>path</parameter> |
| does not exist. |
| All earlier steps in the path must exist, or |
| the <parameter>target</parameter> is returned unchanged. |
| As with the path oriented operators, negative integers that |
| appear in the <parameter>path</parameter> count from the end |
| of JSON arrays. |
| If the last path step is an array index that is out of range, |
| and <parameter>create_if_missing</parameter> is true, the new |
| value is added at the beginning of the array if the index is negative, |
| or at the end of the array if it is positive. |
| </para> |
| <para> |
| <literal>jsonb_set('[{"f1":1,"f2":null},2,null,3]', '{0,f1}', '[2,3,4]', false)</literal> |
| <returnvalue>[{"f1": [2, 3, 4], "f2": null}, 2, null, 3]</returnvalue> |
| </para> |
| <para> |
| <literal>jsonb_set('[{"f1":1,"f2":null},2]', '{0,f3}', '[2,3,4]')</literal> |
| <returnvalue>[{"f1": 1, "f2": null, "f3": [2, 3, 4]}, 2]</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_set_lax</primary> |
| </indexterm> |
| <function>jsonb_set_lax</function> ( <parameter>target</parameter> <type>jsonb</type>, <parameter>path</parameter> <type>text[]</type>, <parameter>new_value</parameter> <type>jsonb</type> <optional>, <parameter>create_if_missing</parameter> <type>boolean</type> <optional>, <parameter>null_value_treatment</parameter> <type>text</type> </optional></optional> ) |
| <returnvalue>jsonb</returnvalue> |
| </para> |
| <para> |
| If <parameter>new_value</parameter> is not <literal>NULL</literal>, |
| behaves identically to <literal>jsonb_set</literal>. Otherwise behaves |
| according to the value |
| of <parameter>null_value_treatment</parameter> which must be one |
| of <literal>'raise_exception'</literal>, |
| <literal>'use_json_null'</literal>, <literal>'delete_key'</literal>, or |
| <literal>'return_target'</literal>. The default is |
| <literal>'use_json_null'</literal>. |
| </para> |
| <para> |
| <literal>jsonb_set_lax('[{"f1":1,"f2":null},2,null,3]', '{0,f1}', null)</literal> |
| <returnvalue>[{"f1":null,"f2":null},2,null,3]</returnvalue> |
| </para> |
| <para> |
| <literal>jsonb_set_lax('[{"f1":99,"f2":null},2]', '{0,f3}', null, true, 'return_target')</literal> |
| <returnvalue>[{"f1": 99, "f2": null}, 2]</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_insert</primary> |
| </indexterm> |
| <function>jsonb_insert</function> ( <parameter>target</parameter> <type>jsonb</type>, <parameter>path</parameter> <type>text[]</type>, <parameter>new_value</parameter> <type>jsonb</type> <optional>, <parameter>insert_after</parameter> <type>boolean</type> </optional> ) |
| <returnvalue>jsonb</returnvalue> |
| </para> |
| <para> |
| Returns <parameter>target</parameter> |
| with <parameter>new_value</parameter> inserted. If the item |
| designated by the <parameter>path</parameter> is an array |
| element, <parameter>new_value</parameter> will be inserted before |
| that item if <parameter>insert_after</parameter> is false (which |
| is the default), or after it |
| if <parameter>insert_after</parameter> is true. If the item |
| designated by the <parameter>path</parameter> is an object |
| field, <parameter>new_value</parameter> will be inserted only if |
| the object does not already contain that key. |
| All earlier steps in the path must exist, or |
| the <parameter>target</parameter> is returned unchanged. |
| As with the path oriented operators, negative integers that |
| appear in the <parameter>path</parameter> count from the end |
| of JSON arrays. |
| If the last path step is an array index that is out of range, the new |
| value is added at the beginning of the array if the index is negative, |
| or at the end of the array if it is positive. |
| </para> |
| <para> |
| <literal>jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"')</literal> |
| <returnvalue>{"a": [0, "new_value", 1, 2]}</returnvalue> |
| </para> |
| <para> |
| <literal>jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"', true)</literal> |
| <returnvalue>{"a": [0, 1, "new_value", 2]}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>json_strip_nulls</primary> |
| </indexterm> |
| <function>json_strip_nulls</function> ( <type>json</type> ) |
| <returnvalue>json</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_strip_nulls</primary> |
| </indexterm> |
| <function>jsonb_strip_nulls</function> ( <type>jsonb</type> ) |
| <returnvalue>jsonb</returnvalue> |
| </para> |
| <para> |
| Deletes all object fields that have null values from the given JSON |
| value, recursively. Null values that are not object fields are |
| untouched. |
| </para> |
| <para> |
| <literal>json_strip_nulls('[{"f1":1, "f2":null}, 2, null, 3]')</literal> |
| <returnvalue>[{"f1":1},2,null,3]</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_path_exists</primary> |
| </indexterm> |
| <function>jsonb_path_exists</function> ( <parameter>target</parameter> <type>jsonb</type>, <parameter>path</parameter> <type>jsonpath</type> <optional>, <parameter>vars</parameter> <type>jsonb</type> <optional>, <parameter>silent</parameter> <type>boolean</type> </optional></optional> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Checks whether the JSON path returns any item for the specified JSON |
| value. |
| If the <parameter>vars</parameter> argument is specified, it must |
| be a JSON object, and its fields provide named values to be |
| substituted into the <type>jsonpath</type> expression. |
| If the <parameter>silent</parameter> argument is specified and |
| is <literal>true</literal>, the function suppresses the same errors |
| as the <literal>@?</literal> and <literal>@@</literal> operators do. |
| </para> |
| <para> |
| <literal>jsonb_path_exists('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min && @ <= $max)', '{"min":2, "max":4}')</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_path_match</primary> |
| </indexterm> |
| <function>jsonb_path_match</function> ( <parameter>target</parameter> <type>jsonb</type>, <parameter>path</parameter> <type>jsonpath</type> <optional>, <parameter>vars</parameter> <type>jsonb</type> <optional>, <parameter>silent</parameter> <type>boolean</type> </optional></optional> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Returns the result of a JSON path predicate check for the specified |
| JSON value. Only the first item of the result is taken into account. |
| If the result is not Boolean, then <literal>NULL</literal> is returned. |
| The optional <parameter>vars</parameter> |
| and <parameter>silent</parameter> arguments act the same as |
| for <function>jsonb_path_exists</function>. |
| </para> |
| <para> |
| <literal>jsonb_path_match('{"a":[1,2,3,4,5]}', 'exists($.a[*] ? (@ >= $min && @ <= $max))', '{"min":2, "max":4}')</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_path_query</primary> |
| </indexterm> |
| <function>jsonb_path_query</function> ( <parameter>target</parameter> <type>jsonb</type>, <parameter>path</parameter> <type>jsonpath</type> <optional>, <parameter>vars</parameter> <type>jsonb</type> <optional>, <parameter>silent</parameter> <type>boolean</type> </optional></optional> ) |
| <returnvalue>setof jsonb</returnvalue> |
| </para> |
| <para> |
| Returns all JSON items returned by the JSON path for the specified |
| JSON value. |
| The optional <parameter>vars</parameter> |
| and <parameter>silent</parameter> arguments act the same as |
| for <function>jsonb_path_exists</function>. |
| </para> |
| <para> |
| <literal>select * from jsonb_path_query('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min && @ <= $max)', '{"min":2, "max":4}')</literal> |
| <returnvalue></returnvalue> |
| <programlisting> |
| jsonb_path_query |
| ------------------ |
| 2 |
| 3 |
| 4 |
| </programlisting> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_path_query_array</primary> |
| </indexterm> |
| <function>jsonb_path_query_array</function> ( <parameter>target</parameter> <type>jsonb</type>, <parameter>path</parameter> <type>jsonpath</type> <optional>, <parameter>vars</parameter> <type>jsonb</type> <optional>, <parameter>silent</parameter> <type>boolean</type> </optional></optional> ) |
| <returnvalue>jsonb</returnvalue> |
| </para> |
| <para> |
| Returns all JSON items returned by the JSON path for the specified |
| JSON value, as a JSON array. |
| The optional <parameter>vars</parameter> |
| and <parameter>silent</parameter> arguments act the same as |
| for <function>jsonb_path_exists</function>. |
| </para> |
| <para> |
| <literal>jsonb_path_query_array('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min && @ <= $max)', '{"min":2, "max":4}')</literal> |
| <returnvalue>[2, 3, 4]</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_path_query_first</primary> |
| </indexterm> |
| <function>jsonb_path_query_first</function> ( <parameter>target</parameter> <type>jsonb</type>, <parameter>path</parameter> <type>jsonpath</type> <optional>, <parameter>vars</parameter> <type>jsonb</type> <optional>, <parameter>silent</parameter> <type>boolean</type> </optional></optional> ) |
| <returnvalue>jsonb</returnvalue> |
| </para> |
| <para> |
| Returns the first JSON item returned by the JSON path for the |
| specified JSON value. Returns <literal>NULL</literal> if there are no |
| results. |
| The optional <parameter>vars</parameter> |
| and <parameter>silent</parameter> arguments act the same as |
| for <function>jsonb_path_exists</function>. |
| </para> |
| <para> |
| <literal>jsonb_path_query_first('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min && @ <= $max)', '{"min":2, "max":4}')</literal> |
| <returnvalue>2</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_path_exists_tz</primary> |
| </indexterm> |
| <function>jsonb_path_exists_tz</function> ( <parameter>target</parameter> <type>jsonb</type>, <parameter>path</parameter> <type>jsonpath</type> <optional>, <parameter>vars</parameter> <type>jsonb</type> <optional>, <parameter>silent</parameter> <type>boolean</type> </optional></optional> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_path_match_tz</primary> |
| </indexterm> |
| <function>jsonb_path_match_tz</function> ( <parameter>target</parameter> <type>jsonb</type>, <parameter>path</parameter> <type>jsonpath</type> <optional>, <parameter>vars</parameter> <type>jsonb</type> <optional>, <parameter>silent</parameter> <type>boolean</type> </optional></optional> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_path_query_tz</primary> |
| </indexterm> |
| <function>jsonb_path_query_tz</function> ( <parameter>target</parameter> <type>jsonb</type>, <parameter>path</parameter> <type>jsonpath</type> <optional>, <parameter>vars</parameter> <type>jsonb</type> <optional>, <parameter>silent</parameter> <type>boolean</type> </optional></optional> ) |
| <returnvalue>setof jsonb</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_path_query_array_tz</primary> |
| </indexterm> |
| <function>jsonb_path_query_array_tz</function> ( <parameter>target</parameter> <type>jsonb</type>, <parameter>path</parameter> <type>jsonpath</type> <optional>, <parameter>vars</parameter> <type>jsonb</type> <optional>, <parameter>silent</parameter> <type>boolean</type> </optional></optional> ) |
| <returnvalue>jsonb</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_path_query_first_tz</primary> |
| </indexterm> |
| <function>jsonb_path_query_first_tz</function> ( <parameter>target</parameter> <type>jsonb</type>, <parameter>path</parameter> <type>jsonpath</type> <optional>, <parameter>vars</parameter> <type>jsonb</type> <optional>, <parameter>silent</parameter> <type>boolean</type> </optional></optional> ) |
| <returnvalue>jsonb</returnvalue> |
| </para> |
| <para> |
| These functions act like their counterparts described above without |
| the <literal>_tz</literal> suffix, except that these functions support |
| comparisons of date/time values that require timezone-aware |
| conversions. The example below requires interpretation of the |
| date-only value <literal>2015-08-02</literal> as a timestamp with time |
| zone, so the result depends on the current |
| <xref linkend="guc-timezone"/> setting. Due to this dependency, these |
| functions are marked as stable, which means these functions cannot be |
| used in indexes. Their counterparts are immutable, and so can be used |
| in indexes; but they will throw errors if asked to make such |
| comparisons. |
| </para> |
| <para> |
| <literal>jsonb_path_exists_tz('["2015-08-01 12:00:00 -05"]', '$[*] ? (@.datetime() < "2015-08-02".datetime())')</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_pretty</primary> |
| </indexterm> |
| <function>jsonb_pretty</function> ( <type>jsonb</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Converts the given JSON value to pretty-printed, indented text. |
| </para> |
| <para> |
| <literal>jsonb_pretty('[{"f1":1,"f2":null}, 2]')</literal> |
| <returnvalue></returnvalue> |
| <programlisting> |
| [ |
| { |
| "f1": 1, |
| "f2": null |
| }, |
| 2 |
| ] |
| </programlisting> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>json_typeof</primary> |
| </indexterm> |
| <function>json_typeof</function> ( <type>json</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_typeof</primary> |
| </indexterm> |
| <function>jsonb_typeof</function> ( <type>jsonb</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Returns the type of the top-level JSON value as a text string. |
| Possible types are |
| <literal>object</literal>, <literal>array</literal>, |
| <literal>string</literal>, <literal>number</literal>, |
| <literal>boolean</literal>, and <literal>null</literal>. |
| (The <literal>null</literal> result should not be confused |
| with an SQL NULL; see the examples.) |
| </para> |
| <para> |
| <literal>json_typeof('-123.4')</literal> |
| <returnvalue>number</returnvalue> |
| </para> |
| <para> |
| <literal>json_typeof('null'::json)</literal> |
| <returnvalue>null</returnvalue> |
| </para> |
| <para> |
| <literal>json_typeof(NULL::json) IS NULL</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| See also <xref linkend="functions-aggregate"/> for the aggregate |
| function <function>json_agg</function> which aggregates record |
| values as JSON, the aggregate function |
| <function>json_object_agg</function> which aggregates pairs of values |
| into a JSON object, and their <type>jsonb</type> equivalents, |
| <function>jsonb_agg</function> and <function>jsonb_object_agg</function>. |
| </para> |
| </sect2> |
| |
| <sect2 id="functions-sqljson-path"> |
| <title>The SQL/JSON Path Language</title> |
| |
| <indexterm zone="functions-sqljson-path"> |
| <primary>SQL/JSON path language</primary> |
| </indexterm> |
| |
| <para> |
| SQL/JSON path expressions specify the items to be retrieved |
| from the JSON data, similar to XPath expressions used |
| for SQL access to XML. In <productname>PostgreSQL</productname>, |
| path expressions are implemented as the <type>jsonpath</type> |
| data type and can use any elements described in |
| <xref linkend="datatype-jsonpath"/>. |
| </para> |
| |
| <para> |
| JSON query functions and operators |
| pass the provided path expression to the <firstterm>path engine</firstterm> |
| for evaluation. If the expression matches the queried JSON data, |
| the corresponding JSON item, or set of items, is returned. |
| Path expressions are written in the SQL/JSON path language |
| and can include arithmetic expressions and functions. |
| </para> |
| |
| <para> |
| A path expression consists of a sequence of elements allowed |
| by the <type>jsonpath</type> data type. |
| The path expression is normally evaluated from left to right, but |
| you can use parentheses to change the order of operations. |
| If the evaluation is successful, a sequence of JSON items is produced, |
| and the evaluation result is returned to the JSON query function |
| that completes the specified computation. |
| </para> |
| |
| <para> |
| To refer to the JSON value being queried (the |
| <firstterm>context item</firstterm>), use the <literal>$</literal> variable |
| in the path expression. It can be followed by one or more |
| <link linkend="type-jsonpath-accessors">accessor operators</link>, |
| which go down the JSON structure level by level to retrieve sub-items |
| of the context item. Each operator that follows deals with the |
| result of the previous evaluation step. |
| </para> |
| |
| <para> |
| For example, suppose you have some JSON data from a GPS tracker that you |
| would like to parse, such as: |
| <programlisting> |
| { |
| "track": { |
| "segments": [ |
| { |
| "location": [ 47.763, 13.4034 ], |
| "start time": "2018-10-14 10:05:14", |
| "HR": 73 |
| }, |
| { |
| "location": [ 47.706, 13.2635 ], |
| "start time": "2018-10-14 10:39:21", |
| "HR": 135 |
| } |
| ] |
| } |
| } |
| </programlisting> |
| </para> |
| |
| <para> |
| To retrieve the available track segments, you need to use the |
| <literal>.<replaceable>key</replaceable></literal> accessor |
| operator to descend through surrounding JSON objects: |
| <programlisting> |
| $.track.segments |
| </programlisting> |
| </para> |
| |
| <para> |
| To retrieve the contents of an array, you typically use the |
| <literal>[*]</literal> operator. For example, |
| the following path will return the location coordinates for all |
| the available track segments: |
| <programlisting> |
| $.track.segments[*].location |
| </programlisting> |
| </para> |
| |
| <para> |
| To return the coordinates of the first segment only, you can |
| specify the corresponding subscript in the <literal>[]</literal> |
| accessor operator. Recall that JSON array indexes are 0-relative: |
| <programlisting> |
| $.track.segments[0].location |
| </programlisting> |
| </para> |
| |
| <para> |
| The result of each path evaluation step can be processed |
| by one or more <type>jsonpath</type> operators and methods |
| listed in <xref linkend="functions-sqljson-path-operators"/>. |
| Each method name must be preceded by a dot. For example, |
| you can get the size of an array: |
| <programlisting> |
| $.track.segments.size() |
| </programlisting> |
| More examples of using <type>jsonpath</type> operators |
| and methods within path expressions appear below in |
| <xref linkend="functions-sqljson-path-operators"/>. |
| </para> |
| |
| <para> |
| When defining a path, you can also use one or more |
| <firstterm>filter expressions</firstterm> that work similarly to the |
| <literal>WHERE</literal> clause in SQL. A filter expression begins with |
| a question mark and provides a condition in parentheses: |
| |
| <programlisting> |
| ? (<replaceable>condition</replaceable>) |
| </programlisting> |
| </para> |
| |
| <para> |
| Filter expressions must be written just after the path evaluation step |
| to which they should apply. The result of that step is filtered to include |
| only those items that satisfy the provided condition. SQL/JSON defines |
| three-valued logic, so the condition can be <literal>true</literal>, <literal>false</literal>, |
| or <literal>unknown</literal>. The <literal>unknown</literal> value |
| plays the same role as SQL <literal>NULL</literal> and can be tested |
| for with the <literal>is unknown</literal> predicate. Further path |
| evaluation steps use only those items for which the filter expression |
| returned <literal>true</literal>. |
| </para> |
| |
| <para> |
| The functions and operators that can be used in filter expressions are |
| listed in <xref linkend="functions-sqljson-filter-ex-table"/>. Within a |
| filter expression, the <literal>@</literal> variable denotes the value |
| being filtered (i.e., one result of the preceding path step). You can |
| write accessor operators after <literal>@</literal> to retrieve component |
| items. |
| </para> |
| |
| <para> |
| For example, suppose you would like to retrieve all heart rate values higher |
| than 130. You can achieve this using the following expression: |
| <programlisting> |
| $.track.segments[*].HR ? (@ > 130) |
| </programlisting> |
| </para> |
| |
| <para> |
| To get the start times of segments with such values, you have to |
| filter out irrelevant segments before returning the start times, so the |
| filter expression is applied to the previous step, and the path used |
| in the condition is different: |
| <programlisting> |
| $.track.segments[*] ? (@.HR > 130)."start time" |
| </programlisting> |
| </para> |
| |
| <para> |
| You can use several filter expressions in sequence, if required. For |
| example, the following expression selects start times of all segments that |
| contain locations with relevant coordinates and high heart rate values: |
| <programlisting> |
| $.track.segments[*] ? (@.location[1] < 13.4) ? (@.HR > 130)."start time" |
| </programlisting> |
| </para> |
| |
| <para> |
| Using filter expressions at different nesting levels is also allowed. |
| The following example first filters all segments by location, and then |
| returns high heart rate values for these segments, if available: |
| <programlisting> |
| $.track.segments[*] ? (@.location[1] < 13.4).HR ? (@ > 130) |
| </programlisting> |
| </para> |
| |
| <para> |
| You can also nest filter expressions within each other: |
| <programlisting> |
| $.track ? (exists(@.segments[*] ? (@.HR > 130))).segments.size() |
| </programlisting> |
| This expression returns the size of the track if it contains any |
| segments with high heart rate values, or an empty sequence otherwise. |
| </para> |
| |
| <para> |
| <productname>PostgreSQL</productname>'s implementation of the SQL/JSON path |
| language has the following deviations from the SQL/JSON standard: |
| </para> |
| |
| <itemizedlist> |
| <listitem> |
| <para> |
| A path expression can be a Boolean predicate, although the SQL/JSON |
| standard allows predicates only in filters. This is necessary for |
| implementation of the <literal>@@</literal> operator. For example, |
| the following <type>jsonpath</type> expression is valid in |
| <productname>PostgreSQL</productname>: |
| <programlisting> |
| $.track.segments[*].HR < 70 |
| </programlisting> |
| </para> |
| </listitem> |
| |
| <listitem> |
| <para> |
| There are minor differences in the interpretation of regular |
| expression patterns used in <literal>like_regex</literal> filters, as |
| described in <xref linkend="jsonpath-regular-expressions"/>. |
| </para> |
| </listitem> |
| </itemizedlist> |
| |
| <sect3 id="strict-and-lax-modes"> |
| <title>Strict and Lax Modes</title> |
| <para> |
| When you query JSON data, the path expression may not match the |
| actual JSON data structure. An attempt to access a non-existent |
| member of an object or element of an array results in a |
| structural error. SQL/JSON path expressions have two modes |
| of handling structural errors: |
| </para> |
| |
| <itemizedlist> |
| <listitem> |
| <para> |
| lax (default) — the path engine implicitly adapts |
| the queried data to the specified path. |
| Any remaining structural errors are suppressed and converted |
| to empty SQL/JSON sequences. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| strict — if a structural error occurs, an error is raised. |
| </para> |
| </listitem> |
| </itemizedlist> |
| |
| <para> |
| The lax mode facilitates matching of a JSON document structure and path |
| expression if the JSON data does not conform to the expected schema. |
| If an operand does not match the requirements of a particular operation, |
| it can be automatically wrapped as an SQL/JSON array or unwrapped by |
| converting its elements into an SQL/JSON sequence before performing |
| this operation. Besides, comparison operators automatically unwrap their |
| operands in the lax mode, so you can compare SQL/JSON arrays |
| out-of-the-box. An array of size 1 is considered equal to its sole element. |
| Automatic unwrapping is not performed only when: |
| <itemizedlist> |
| <listitem> |
| <para> |
| The path expression contains <literal>type()</literal> or |
| <literal>size()</literal> methods that return the type |
| and the number of elements in the array, respectively. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| The queried JSON data contain nested arrays. In this case, only |
| the outermost array is unwrapped, while all the inner arrays |
| remain unchanged. Thus, implicit unwrapping can only go one |
| level down within each path evaluation step. |
| </para> |
| </listitem> |
| </itemizedlist> |
| </para> |
| |
| <para> |
| For example, when querying the GPS data listed above, you can |
| abstract from the fact that it stores an array of segments |
| when using the lax mode: |
| <programlisting> |
| lax $.track.segments.location |
| </programlisting> |
| </para> |
| |
| <para> |
| In the strict mode, the specified path must exactly match the structure of |
| the queried JSON document to return an SQL/JSON item, so using this |
| path expression will cause an error. To get the same result as in |
| the lax mode, you have to explicitly unwrap the |
| <literal>segments</literal> array: |
| <programlisting> |
| strict $.track.segments[*].location |
| </programlisting> |
| </para> |
| |
| <para> |
| The <literal>.**</literal> accessor can lead to surprising results |
| when using the lax mode. For instance, the following query selects every |
| <literal>HR</literal> value twice: |
| <programlisting> |
| lax $.**.HR |
| </programlisting> |
| This happens because the <literal>.**</literal> accessor selects both |
| the <literal>segments</literal> array and each of its elements, while |
| the <literal>.HR</literal> accessor automatically unwraps arrays when |
| using the lax mode. To avoid surprising results, we recommend using |
| the <literal>.**</literal> accessor only in the strict mode. The |
| following query selects each <literal>HR</literal> value just once: |
| <programlisting> |
| strict $.**.HR |
| </programlisting> |
| </para> |
| |
| </sect3> |
| |
| <sect3 id="functions-sqljson-path-operators"> |
| <title>SQL/JSON Path Operators and Methods</title> |
| |
| <para> |
| <xref linkend="functions-sqljson-op-table"/> shows the operators and |
| methods available in <type>jsonpath</type>. Note that while the unary |
| operators and methods can be applied to multiple values resulting from a |
| preceding path step, the binary operators (addition etc.) can only be |
| applied to single values. |
| </para> |
| |
| <table id="functions-sqljson-op-table"> |
| <title><type>jsonpath</type> Operators and Methods</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Operator/Method |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>number</replaceable> <literal>+</literal> <replaceable>number</replaceable> |
| <returnvalue><replaceable>number</replaceable></returnvalue> |
| </para> |
| <para> |
| Addition |
| </para> |
| <para> |
| <literal>jsonb_path_query('[2]', '$[0] + 3')</literal> |
| <returnvalue>5</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <literal>+</literal> <replaceable>number</replaceable> |
| <returnvalue><replaceable>number</replaceable></returnvalue> |
| </para> |
| <para> |
| Unary plus (no operation); unlike addition, this can iterate over |
| multiple values |
| </para> |
| <para> |
| <literal>jsonb_path_query_array('{"x": [2,3,4]}', '+ $.x')</literal> |
| <returnvalue>[2, 3, 4]</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>number</replaceable> <literal>-</literal> <replaceable>number</replaceable> |
| <returnvalue><replaceable>number</replaceable></returnvalue> |
| </para> |
| <para> |
| Subtraction |
| </para> |
| <para> |
| <literal>jsonb_path_query('[2]', '7 - $[0]')</literal> |
| <returnvalue>5</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <literal>-</literal> <replaceable>number</replaceable> |
| <returnvalue><replaceable>number</replaceable></returnvalue> |
| </para> |
| <para> |
| Negation; unlike subtraction, this can iterate over |
| multiple values |
| </para> |
| <para> |
| <literal>jsonb_path_query_array('{"x": [2,3,4]}', '- $.x')</literal> |
| <returnvalue>[-2, -3, -4]</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>number</replaceable> <literal>*</literal> <replaceable>number</replaceable> |
| <returnvalue><replaceable>number</replaceable></returnvalue> |
| </para> |
| <para> |
| Multiplication |
| </para> |
| <para> |
| <literal>jsonb_path_query('[4]', '2 * $[0]')</literal> |
| <returnvalue>8</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>number</replaceable> <literal>/</literal> <replaceable>number</replaceable> |
| <returnvalue><replaceable>number</replaceable></returnvalue> |
| </para> |
| <para> |
| Division |
| </para> |
| <para> |
| <literal>jsonb_path_query('[8.5]', '$[0] / 2')</literal> |
| <returnvalue>4.2500000000000000</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>number</replaceable> <literal>%</literal> <replaceable>number</replaceable> |
| <returnvalue><replaceable>number</replaceable></returnvalue> |
| </para> |
| <para> |
| Modulo (remainder) |
| </para> |
| <para> |
| <literal>jsonb_path_query('[32]', '$[0] % 10')</literal> |
| <returnvalue>2</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>value</replaceable> <literal>.</literal> <literal>type()</literal> |
| <returnvalue><replaceable>string</replaceable></returnvalue> |
| </para> |
| <para> |
| Type of the JSON item (see <function>json_typeof</function>) |
| </para> |
| <para> |
| <literal>jsonb_path_query_array('[1, "2", {}]', '$[*].type()')</literal> |
| <returnvalue>["number", "string", "object"]</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>value</replaceable> <literal>.</literal> <literal>size()</literal> |
| <returnvalue><replaceable>number</replaceable></returnvalue> |
| </para> |
| <para> |
| Size of the JSON item (number of array elements, or 1 if not an |
| array) |
| </para> |
| <para> |
| <literal>jsonb_path_query('{"m": [11, 15]}', '$.m.size()')</literal> |
| <returnvalue>2</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>value</replaceable> <literal>.</literal> <literal>double()</literal> |
| <returnvalue><replaceable>number</replaceable></returnvalue> |
| </para> |
| <para> |
| Approximate floating-point number converted from a JSON number or |
| string |
| </para> |
| <para> |
| <literal>jsonb_path_query('{"len": "1.9"}', '$.len.double() * 2')</literal> |
| <returnvalue>3.8</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>number</replaceable> <literal>.</literal> <literal>ceiling()</literal> |
| <returnvalue><replaceable>number</replaceable></returnvalue> |
| </para> |
| <para> |
| Nearest integer greater than or equal to the given number |
| </para> |
| <para> |
| <literal>jsonb_path_query('{"h": 1.3}', '$.h.ceiling()')</literal> |
| <returnvalue>2</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>number</replaceable> <literal>.</literal> <literal>floor()</literal> |
| <returnvalue><replaceable>number</replaceable></returnvalue> |
| </para> |
| <para> |
| Nearest integer less than or equal to the given number |
| </para> |
| <para> |
| <literal>jsonb_path_query('{"h": 1.7}', '$.h.floor()')</literal> |
| <returnvalue>1</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>number</replaceable> <literal>.</literal> <literal>abs()</literal> |
| <returnvalue><replaceable>number</replaceable></returnvalue> |
| </para> |
| <para> |
| Absolute value of the given number |
| </para> |
| <para> |
| <literal>jsonb_path_query('{"z": -0.3}', '$.z.abs()')</literal> |
| <returnvalue>0.3</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>string</replaceable> <literal>.</literal> <literal>datetime()</literal> |
| <returnvalue><replaceable>datetime_type</replaceable></returnvalue> |
| (see note) |
| </para> |
| <para> |
| Date/time value converted from a string |
| </para> |
| <para> |
| <literal>jsonb_path_query('["2015-8-1", "2015-08-12"]', '$[*] ? (@.datetime() < "2015-08-2".datetime())')</literal> |
| <returnvalue>"2015-8-1"</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>string</replaceable> <literal>.</literal> <literal>datetime(<replaceable>template</replaceable>)</literal> |
| <returnvalue><replaceable>datetime_type</replaceable></returnvalue> |
| (see note) |
| </para> |
| <para> |
| Date/time value converted from a string using the |
| specified <function>to_timestamp</function> template |
| </para> |
| <para> |
| <literal>jsonb_path_query_array('["12:30", "18:40"]', '$[*].datetime("HH24:MI")')</literal> |
| <returnvalue>["12:30:00", "18:40:00"]</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>object</replaceable> <literal>.</literal> <literal>keyvalue()</literal> |
| <returnvalue><replaceable>array</replaceable></returnvalue> |
| </para> |
| <para> |
| The object's key-value pairs, represented as an array of objects |
| containing three fields: <literal>"key"</literal>, |
| <literal>"value"</literal>, and <literal>"id"</literal>; |
| <literal>"id"</literal> is a unique identifier of the object the |
| key-value pair belongs to |
| </para> |
| <para> |
| <literal>jsonb_path_query_array('{"x": "20", "y": 32}', '$.keyvalue()')</literal> |
| <returnvalue>[{"id": 0, "key": "x", "value": "20"}, {"id": 0, "key": "y", "value": 32}]</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <note> |
| <para> |
| The result type of the <literal>datetime()</literal> and |
| <literal>datetime(<replaceable>template</replaceable>)</literal> |
| methods can be <type>date</type>, <type>timetz</type>, <type>time</type>, |
| <type>timestamptz</type>, or <type>timestamp</type>. |
| Both methods determine their result type dynamically. |
| </para> |
| <para> |
| The <literal>datetime()</literal> method sequentially tries to |
| match its input string to the ISO formats |
| for <type>date</type>, <type>timetz</type>, <type>time</type>, |
| <type>timestamptz</type>, and <type>timestamp</type>. It stops on |
| the first matching format and emits the corresponding data type. |
| </para> |
| <para> |
| The <literal>datetime(<replaceable>template</replaceable>)</literal> |
| method determines the result type according to the fields used in the |
| provided template string. |
| </para> |
| <para> |
| The <literal>datetime()</literal> and |
| <literal>datetime(<replaceable>template</replaceable>)</literal> methods |
| use the same parsing rules as the <literal>to_timestamp</literal> SQL |
| function does (see <xref linkend="functions-formatting"/>), with three |
| exceptions. First, these methods don't allow unmatched template |
| patterns. Second, only the following separators are allowed in the |
| template string: minus sign, period, solidus (slash), comma, apostrophe, |
| semicolon, colon and space. Third, separators in the template string |
| must exactly match the input string. |
| </para> |
| <para> |
| If different date/time types need to be compared, an implicit cast is |
| applied. A <type>date</type> value can be cast to <type>timestamp</type> |
| or <type>timestamptz</type>, <type>timestamp</type> can be cast to |
| <type>timestamptz</type>, and <type>time</type> to <type>timetz</type>. |
| However, all but the first of these conversions depend on the current |
| <xref linkend="guc-timezone"/> setting, and thus can only be performed |
| within timezone-aware <type>jsonpath</type> functions. |
| </para> |
| </note> |
| |
| <para> |
| <xref linkend="functions-sqljson-filter-ex-table"/> shows the available |
| filter expression elements. |
| </para> |
| |
| <table id="functions-sqljson-filter-ex-table"> |
| <title><type>jsonpath</type> Filter Expression Elements</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Predicate/Value |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>value</replaceable> <literal>==</literal> <replaceable>value</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Equality comparison (this, and the other comparison operators, work on |
| all JSON scalar values) |
| </para> |
| <para> |
| <literal>jsonb_path_query_array('[1, "a", 1, 3]', '$[*] ? (@ == 1)')</literal> |
| <returnvalue>[1, 1]</returnvalue> |
| </para> |
| <para> |
| <literal>jsonb_path_query_array('[1, "a", 1, 3]', '$[*] ? (@ == "a")')</literal> |
| <returnvalue>["a"]</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>value</replaceable> <literal>!=</literal> <replaceable>value</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <replaceable>value</replaceable> <literal><></literal> <replaceable>value</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Non-equality comparison |
| </para> |
| <para> |
| <literal>jsonb_path_query_array('[1, 2, 1, 3]', '$[*] ? (@ != 1)')</literal> |
| <returnvalue>[2, 3]</returnvalue> |
| </para> |
| <para> |
| <literal>jsonb_path_query_array('["a", "b", "c"]', '$[*] ? (@ <> "b")')</literal> |
| <returnvalue>["a", "c"]</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>value</replaceable> <literal><</literal> <replaceable>value</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Less-than comparison |
| </para> |
| <para> |
| <literal>jsonb_path_query_array('[1, 2, 3]', '$[*] ? (@ < 2)')</literal> |
| <returnvalue>[1]</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>value</replaceable> <literal><=</literal> <replaceable>value</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Less-than-or-equal-to comparison |
| </para> |
| <para> |
| <literal>jsonb_path_query_array('["a", "b", "c"]', '$[*] ? (@ <= "b")')</literal> |
| <returnvalue>["a", "b"]</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>value</replaceable> <literal>></literal> <replaceable>value</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Greater-than comparison |
| </para> |
| <para> |
| <literal>jsonb_path_query_array('[1, 2, 3]', '$[*] ? (@ > 2)')</literal> |
| <returnvalue>[3]</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>value</replaceable> <literal>>=</literal> <replaceable>value</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Greater-than-or-equal-to comparison |
| </para> |
| <para> |
| <literal>jsonb_path_query_array('[1, 2, 3]', '$[*] ? (@ >= 2)')</literal> |
| <returnvalue>[2, 3]</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <literal>true</literal> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| JSON constant <literal>true</literal> |
| </para> |
| <para> |
| <literal>jsonb_path_query('[{"name": "John", "parent": false}, {"name": "Chris", "parent": true}]', '$[*] ? (@.parent == true)')</literal> |
| <returnvalue>{"name": "Chris", "parent": true}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <literal>false</literal> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| JSON constant <literal>false</literal> |
| </para> |
| <para> |
| <literal>jsonb_path_query('[{"name": "John", "parent": false}, {"name": "Chris", "parent": true}]', '$[*] ? (@.parent == false)')</literal> |
| <returnvalue>{"name": "John", "parent": false}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <literal>null</literal> |
| <returnvalue><replaceable>value</replaceable></returnvalue> |
| </para> |
| <para> |
| JSON constant <literal>null</literal> (note that, unlike in SQL, |
| comparison to <literal>null</literal> works normally) |
| </para> |
| <para> |
| <literal>jsonb_path_query('[{"name": "Mary", "job": null}, {"name": "Michael", "job": "driver"}]', '$[*] ? (@.job == null) .name')</literal> |
| <returnvalue>"Mary"</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>boolean</replaceable> <literal>&&</literal> <replaceable>boolean</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Boolean AND |
| </para> |
| <para> |
| <literal>jsonb_path_query('[1, 3, 7]', '$[*] ? (@ > 1 && @ < 5)')</literal> |
| <returnvalue>3</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>boolean</replaceable> <literal>||</literal> <replaceable>boolean</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Boolean OR |
| </para> |
| <para> |
| <literal>jsonb_path_query('[1, 3, 7]', '$[*] ? (@ < 1 || @ > 5)')</literal> |
| <returnvalue>7</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <literal>!</literal> <replaceable>boolean</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Boolean NOT |
| </para> |
| <para> |
| <literal>jsonb_path_query('[1, 3, 7]', '$[*] ? (!(@ < 5))')</literal> |
| <returnvalue>7</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>boolean</replaceable> <literal>is unknown</literal> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Tests whether a Boolean condition is <literal>unknown</literal>. |
| </para> |
| <para> |
| <literal>jsonb_path_query('[-1, 2, 7, "foo"]', '$[*] ? ((@ > 0) is unknown)')</literal> |
| <returnvalue>"foo"</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>string</replaceable> <literal>like_regex</literal> <replaceable>string</replaceable> <optional> <literal>flag</literal> <replaceable>string</replaceable> </optional> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Tests whether the first operand matches the regular expression |
| given by the second operand, optionally with modifications |
| described by a string of <literal>flag</literal> characters (see |
| <xref linkend="jsonpath-regular-expressions"/>). |
| </para> |
| <para> |
| <literal>jsonb_path_query_array('["abc", "abd", "aBdC", "abdacb", "babc"]', '$[*] ? (@ like_regex "^ab.*c")')</literal> |
| <returnvalue>["abc", "abdacb"]</returnvalue> |
| </para> |
| <para> |
| <literal>jsonb_path_query_array('["abc", "abd", "aBdC", "abdacb", "babc"]', '$[*] ? (@ like_regex "^ab.*c" flag "i")')</literal> |
| <returnvalue>["abc", "aBdC", "abdacb"]</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <replaceable>string</replaceable> <literal>starts with</literal> <replaceable>string</replaceable> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Tests whether the second operand is an initial substring of the first |
| operand. |
| </para> |
| <para> |
| <literal>jsonb_path_query('["John Smith", "Mary Stone", "Bob Johnson"]', '$[*] ? (@ starts with "John")')</literal> |
| <returnvalue>"John Smith"</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <literal>exists</literal> <literal>(</literal> <replaceable>path_expression</replaceable> <literal>)</literal> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Tests whether a path expression matches at least one SQL/JSON item. |
| Returns <literal>unknown</literal> if the path expression would result |
| in an error; the second example uses this to avoid a no-such-key error |
| in strict mode. |
| </para> |
| <para> |
| <literal>jsonb_path_query('{"x": [1, 2], "y": [2, 4]}', 'strict $.* ? (exists (@ ? (@[*] > 2)))')</literal> |
| <returnvalue>[2, 4]</returnvalue> |
| </para> |
| <para> |
| <literal>jsonb_path_query_array('{"value": 41}', 'strict $ ? (exists (@.name)) .name')</literal> |
| <returnvalue>[]</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| </sect3> |
| |
| <sect3 id="jsonpath-regular-expressions"> |
| <title>SQL/JSON Regular Expressions</title> |
| |
| <indexterm zone="jsonpath-regular-expressions"> |
| <primary><literal>LIKE_REGEX</literal></primary> |
| <secondary>in SQL/JSON</secondary> |
| </indexterm> |
| |
| <para> |
| SQL/JSON path expressions allow matching text to a regular expression |
| with the <literal>like_regex</literal> filter. For example, the |
| following SQL/JSON path query would case-insensitively match all |
| strings in an array that start with an English vowel: |
| <programlisting> |
| $[*] ? (@ like_regex "^[aeiou]" flag "i") |
| </programlisting> |
| </para> |
| |
| <para> |
| The optional <literal>flag</literal> string may include one or more of |
| the characters |
| <literal>i</literal> for case-insensitive match, |
| <literal>m</literal> to allow <literal>^</literal> |
| and <literal>$</literal> to match at newlines, |
| <literal>s</literal> to allow <literal>.</literal> to match a newline, |
| and <literal>q</literal> to quote the whole pattern (reducing the |
| behavior to a simple substring match). |
| </para> |
| |
| <para> |
| The SQL/JSON standard borrows its definition for regular expressions |
| from the <literal>LIKE_REGEX</literal> operator, which in turn uses the |
| XQuery standard. PostgreSQL does not currently support the |
| <literal>LIKE_REGEX</literal> operator. Therefore, |
| the <literal>like_regex</literal> filter is implemented using the |
| POSIX regular expression engine described in |
| <xref linkend="functions-posix-regexp"/>. This leads to various minor |
| discrepancies from standard SQL/JSON behavior, which are cataloged in |
| <xref linkend="posix-vs-xquery"/>. |
| Note, however, that the flag-letter incompatibilities described there |
| do not apply to SQL/JSON, as it translates the XQuery flag letters to |
| match what the POSIX engine expects. |
| </para> |
| |
| <para> |
| Keep in mind that the pattern argument of <literal>like_regex</literal> |
| is a JSON path string literal, written according to the rules given in |
| <xref linkend="datatype-jsonpath"/>. This means in particular that any |
| backslashes you want to use in the regular expression must be doubled. |
| For example, to match string values of the root document that contain |
| only digits: |
| <programlisting> |
| $.* ? (@ like_regex "^\\d+$") |
| </programlisting> |
| </para> |
| </sect3> |
| </sect2> |
| </sect1> |
| |
| <sect1 id="functions-sequence"> |
| <title>Sequence Manipulation Functions</title> |
| |
| <indexterm> |
| <primary>sequence</primary> |
| </indexterm> |
| |
| <para> |
| This section describes functions for operating on <firstterm>sequence |
| objects</firstterm>, also called sequence generators or just sequences. |
| Sequence objects are special single-row tables created with <xref |
| linkend="sql-createsequence"/>. |
| Sequence objects are commonly used to generate unique identifiers |
| for rows of a table. The sequence functions, listed in <xref |
| linkend="functions-sequence-table"/>, provide simple, multiuser-safe |
| methods for obtaining successive sequence values from sequence |
| objects. |
| </para> |
| |
| <table id="functions-sequence-table"> |
| <title>Sequence Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>nextval</primary> |
| </indexterm> |
| <function>nextval</function> ( <type>regclass</type> ) |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para> |
| Advances the sequence object to its next value and returns that value. |
| This is done atomically: even if multiple sessions |
| execute <function>nextval</function> concurrently, each will safely |
| receive a distinct sequence value. |
| If the sequence object has been created with default parameters, |
| successive <function>nextval</function> calls will return successive |
| values beginning with 1. Other behaviors can be obtained by using |
| appropriate parameters in the <xref linkend="sql-createsequence"/> |
| command. |
| </para> |
| <para> |
| This function requires <literal>USAGE</literal> |
| or <literal>UPDATE</literal> privilege on the sequence. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>setval</primary> |
| </indexterm> |
| <function>setval</function> ( <type>regclass</type>, <type>bigint</type> <optional>, <type>boolean</type> </optional> ) |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para> |
| Sets the sequence object's current value, and optionally |
| its <literal>is_called</literal> flag. The two-parameter |
| form sets the sequence's <literal>last_value</literal> field to the |
| specified value and sets its <literal>is_called</literal> field to |
| <literal>true</literal>, meaning that the next |
| <function>nextval</function> will advance the sequence before |
| returning a value. The value that will be reported |
| by <function>currval</function> is also set to the specified value. |
| In the three-parameter form, <literal>is_called</literal> can be set |
| to either <literal>true</literal> |
| or <literal>false</literal>. <literal>true</literal> has the same |
| effect as the two-parameter form. If it is set |
| to <literal>false</literal>, the next <function>nextval</function> |
| will return exactly the specified value, and sequence advancement |
| commences with the following <function>nextval</function>. |
| Furthermore, the value reported by <function>currval</function> is not |
| changed in this case. For example, |
| <programlisting> |
| SELECT setval('myseq', 42); <lineannotation>Next <function>nextval</function> will return 43</lineannotation> |
| SELECT setval('myseq', 42, true); <lineannotation>Same as above</lineannotation> |
| SELECT setval('myseq', 42, false); <lineannotation>Next <function>nextval</function> will return 42</lineannotation> |
| </programlisting> |
| The result returned by <function>setval</function> is just the value of its |
| second argument. |
| </para> |
| <para> |
| This function requires <literal>UPDATE</literal> privilege on the |
| sequence. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>currval</primary> |
| </indexterm> |
| <function>currval</function> ( <type>regclass</type> ) |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para> |
| Returns the value most recently obtained |
| by <function>nextval</function> for this sequence in the current |
| session. (An error is reported if <function>nextval</function> 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 <function>nextval</function> since |
| the current session did. |
| </para> |
| <para> |
| This function requires <literal>USAGE</literal> |
| or <literal>SELECT</literal> privilege on the sequence. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>lastval</primary> |
| </indexterm> |
| <function>lastval</function> () |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para> |
| Returns the value most recently returned by |
| <function>nextval</function> in the current session. This function is |
| identical to <function>currval</function>, except that instead |
| of taking the sequence name as an argument it refers to whichever |
| sequence <function>nextval</function> was most recently applied to |
| in the current session. It is an error to call |
| <function>lastval</function> if <function>nextval</function> |
| has not yet been called in the current session. |
| </para> |
| <para> |
| This function requires <literal>USAGE</literal> |
| or <literal>SELECT</literal> privilege on the last used sequence. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <caution> |
| <para> |
| To avoid blocking concurrent transactions that obtain numbers from |
| the same sequence, the value obtained by <function>nextval</function> |
| is not reclaimed for re-use if the calling transaction later aborts. |
| This means that transaction aborts or database crashes can result in |
| gaps in the sequence of assigned values. That can happen without a |
| transaction abort, too. For example an <command>INSERT</command> with |
| an <literal>ON CONFLICT</literal> clause will compute the to-be-inserted |
| tuple, including doing any required <function>nextval</function> |
| calls, before detecting any conflict that would cause it to follow |
| the <literal>ON CONFLICT</literal> rule instead. |
| Thus, <productname>PostgreSQL</productname> sequence |
| objects <emphasis>cannot be used to obtain <quote>gapless</quote> |
| sequences</emphasis>. |
| </para> |
| |
| <para> |
| Likewise, sequence state changes made by <function>setval</function> |
| are immediately visible to other transactions, and are not undone if |
| the calling transaction rolls back. |
| </para> |
| |
| <para> |
| If the database cluster crashes before committing a transaction |
| containing a <function>nextval</function> |
| or <function>setval</function> call, the sequence state change might |
| not have made its way to persistent storage, so that it is uncertain |
| whether the sequence will have its original or updated state after the |
| cluster restarts. This is harmless for usage of the sequence within |
| the database, since other effects of uncommitted transactions will not |
| be visible either. However, if you wish to use a sequence value for |
| persistent outside-the-database purposes, make sure that the |
| <function>nextval</function> call has been committed before doing so. |
| </para> |
| </caution> |
| |
| <para> |
| The sequence to be operated on by a sequence function is specified by |
| a <type>regclass</type> argument, which is simply the OID of the sequence in the |
| <structname>pg_class</structname> system catalog. You do not have to look up the |
| OID by hand, however, since the <type>regclass</type> data type's input |
| converter will do the work for you. See <xref linkend="datatype-oid"/> |
| for details. |
| </para> |
| </sect1> |
| |
| |
| <sect1 id="functions-conditional"> |
| <title>Conditional Expressions</title> |
| |
| <indexterm> |
| <primary>CASE</primary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>conditional expression</primary> |
| </indexterm> |
| |
| <para> |
| This section describes the <acronym>SQL</acronym>-compliant conditional expressions |
| available in <productname>PostgreSQL</productname>. |
| </para> |
| |
| <tip> |
| <para> |
| If your needs go beyond the capabilities of these conditional |
| expressions, you might want to consider writing a server-side function |
| in a more expressive programming language. |
| </para> |
| </tip> |
| |
| <note> |
| <para> |
| Although <token>COALESCE</token>, <token>GREATEST</token>, and |
| <token>LEAST</token> are syntactically similar to functions, they are |
| not ordinary functions, and thus cannot be used with explicit |
| <token>VARIADIC</token> array arguments. |
| </para> |
| </note> |
| |
| <sect2 id="functions-case"> |
| <title><literal>CASE</literal></title> |
| |
| <para> |
| The <acronym>SQL</acronym> <token>CASE</token> expression is a |
| generic conditional expression, similar to if/else statements in |
| other programming languages: |
| |
| <synopsis> |
| CASE WHEN <replaceable>condition</replaceable> THEN <replaceable>result</replaceable> |
| <optional>WHEN ...</optional> |
| <optional>ELSE <replaceable>result</replaceable></optional> |
| END |
| </synopsis> |
| |
| <token>CASE</token> clauses can be used wherever |
| an expression is valid. Each <replaceable>condition</replaceable> is an |
| expression that returns a <type>boolean</type> result. If the condition's |
| result is true, the value of the <token>CASE</token> expression is the |
| <replaceable>result</replaceable> that follows the condition, and the |
| remainder of the <token>CASE</token> expression is not processed. If the |
| condition's result is not true, any subsequent <token>WHEN</token> clauses |
| are examined in the same manner. If no <token>WHEN</token> |
| <replaceable>condition</replaceable> yields true, the value of the |
| <token>CASE</token> expression is the <replaceable>result</replaceable> of the |
| <token>ELSE</token> clause. If the <token>ELSE</token> clause is |
| omitted and no condition is true, the result is null. |
| </para> |
| |
| <para> |
| An example: |
| <screen> |
| SELECT * FROM test; |
| |
| a |
| --- |
| 1 |
| 2 |
| 3 |
| |
| |
| SELECT a, |
| CASE WHEN a=1 THEN 'one' |
| WHEN a=2 THEN 'two' |
| ELSE 'other' |
| END |
| FROM test; |
| |
| a | case |
| ---+------- |
| 1 | one |
| 2 | two |
| 3 | other |
| </screen> |
| </para> |
| |
| <para> |
| The data types of all the <replaceable>result</replaceable> |
| expressions must be convertible to a single output type. |
| See <xref linkend="typeconv-union-case"/> for more details. |
| </para> |
| |
| <para> |
| There is a <quote>simple</quote> form of <token>CASE</token> expression |
| that is a variant of the general form above: |
| |
| <synopsis> |
| CASE <replaceable>expression</replaceable> |
| WHEN <replaceable>value</replaceable> THEN <replaceable>result</replaceable> |
| <optional>WHEN ...</optional> |
| <optional>ELSE <replaceable>result</replaceable></optional> |
| END |
| </synopsis> |
| |
| The first |
| <replaceable>expression</replaceable> is computed, then compared to |
| each of the <replaceable>value</replaceable> expressions in the |
| <token>WHEN</token> clauses until one is found that is equal to it. If |
| no match is found, the <replaceable>result</replaceable> of the |
| <token>ELSE</token> clause (or a null value) is returned. This is similar |
| to the <function>switch</function> statement in C. |
| </para> |
| |
| <para> |
| The example above can be written using the simple |
| <token>CASE</token> syntax: |
| <screen> |
| SELECT a, |
| CASE a WHEN 1 THEN 'one' |
| WHEN 2 THEN 'two' |
| ELSE 'other' |
| END |
| FROM test; |
| |
| a | case |
| ---+------- |
| 1 | one |
| 2 | two |
| 3 | other |
| </screen> |
| </para> |
| |
| <para> |
| A <token>CASE</token> expression does not evaluate any subexpressions |
| that are not needed to determine the result. For example, this is a |
| possible way of avoiding a division-by-zero failure: |
| <programlisting> |
| SELECT ... WHERE CASE WHEN x <> 0 THEN y/x > 1.5 ELSE false END; |
| </programlisting> |
| </para> |
| |
| <note> |
| <para> |
| As described in <xref linkend="syntax-express-eval"/>, there are various |
| situations in which subexpressions of an expression are evaluated at |
| different times, so that the principle that <quote><token>CASE</token> |
| evaluates only necessary subexpressions</quote> is not ironclad. For |
| example a constant <literal>1/0</literal> subexpression will usually result in |
| a division-by-zero failure at planning time, even if it's within |
| a <token>CASE</token> arm that would never be entered at run time. |
| </para> |
| </note> |
| </sect2> |
| |
| <sect2 id="functions-coalesce-nvl-ifnull"> |
| <title><literal>COALESCE</literal></title> |
| |
| <indexterm> |
| <primary>COALESCE</primary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>NVL</primary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>IFNULL</primary> |
| </indexterm> |
| |
| <synopsis> |
| <function>COALESCE</function>(<replaceable>value</replaceable> <optional>, ...</optional>) |
| </synopsis> |
| |
| <para> |
| The <function>COALESCE</function> function returns the first of its |
| arguments that is not null. Null is returned only if all arguments |
| are null. It is often used to substitute a default value for |
| null values when data is retrieved for display, for example: |
| <programlisting> |
| SELECT COALESCE(description, short_description, '(none)') ... |
| </programlisting> |
| This returns <varname>description</varname> if it is not null, otherwise |
| <varname>short_description</varname> if it is not null, otherwise <literal>(none)</literal>. |
| </para> |
| |
| <para> |
| The arguments must all be convertible to a common data type, which |
| will be the type of the result (see |
| <xref linkend="typeconv-union-case"/> for details). |
| </para> |
| |
| <para> |
| Like a <token>CASE</token> expression, <function>COALESCE</function> only |
| evaluates the arguments that are needed to determine the result; |
| that is, arguments to the right of the first non-null argument are |
| not evaluated. This SQL-standard function provides capabilities similar |
| to <function>NVL</function> and <function>IFNULL</function>, which are used in some other |
| database systems. |
| </para> |
| </sect2> |
| |
| <sect2 id="functions-nullif"> |
| <title><literal>NULLIF</literal></title> |
| |
| <indexterm> |
| <primary>NULLIF</primary> |
| </indexterm> |
| |
| <synopsis> |
| <function>NULLIF</function>(<replaceable>value1</replaceable>, <replaceable>value2</replaceable>) |
| </synopsis> |
| |
| <para> |
| The <function>NULLIF</function> function returns a null value if |
| <replaceable>value1</replaceable> equals <replaceable>value2</replaceable>; |
| otherwise it returns <replaceable>value1</replaceable>. |
| This can be used to perform the inverse operation of the |
| <function>COALESCE</function> example given above: |
| <programlisting> |
| SELECT NULLIF(value, '(none)') ... |
| </programlisting> |
| In this example, if <literal>value</literal> is <literal>(none)</literal>, |
| null is returned, otherwise the value of <literal>value</literal> |
| is returned. |
| </para> |
| |
| <para> |
| The two arguments must be of comparable types. |
| To be specific, they are compared exactly as if you had |
| written <literal><replaceable>value1</replaceable> |
| = <replaceable>value2</replaceable></literal>, so there must be a |
| suitable <literal>=</literal> operator available. |
| </para> |
| |
| <para> |
| The result has the same type as the first argument — but there is |
| a subtlety. What is actually returned is the first argument of the |
| implied <literal>=</literal> operator, and in some cases that will have |
| been promoted to match the second argument's type. For |
| example, <literal>NULLIF(1, 2.2)</literal> yields <type>numeric</type>, |
| because there is no <type>integer</type> <literal>=</literal> |
| <type>numeric</type> operator, |
| only <type>numeric</type> <literal>=</literal> <type>numeric</type>. |
| </para> |
| |
| </sect2> |
| |
| <sect2 id="functions-greatest-least"> |
| <title><literal>GREATEST</literal> and <literal>LEAST</literal></title> |
| |
| <indexterm> |
| <primary>GREATEST</primary> |
| </indexterm> |
| <indexterm> |
| <primary>LEAST</primary> |
| </indexterm> |
| |
| <synopsis> |
| <function>GREATEST</function>(<replaceable>value</replaceable> <optional>, ...</optional>) |
| </synopsis> |
| <synopsis> |
| <function>LEAST</function>(<replaceable>value</replaceable> <optional>, ...</optional>) |
| </synopsis> |
| |
| <para> |
| The <function>GREATEST</function> and <function>LEAST</function> functions select the |
| largest or smallest value from a list of any number of expressions. |
| The expressions must all be convertible to a common data type, which |
| will be the type of the result |
| (see <xref linkend="typeconv-union-case"/> for details). NULL values |
| in the list are ignored. The result will be NULL only if all the |
| expressions evaluate to NULL. |
| </para> |
| |
| <para> |
| Note that <function>GREATEST</function> and <function>LEAST</function> are not in |
| the SQL standard, but are a common extension. Some other databases |
| make them return NULL if any argument is NULL, rather than only when |
| all are NULL. |
| </para> |
| </sect2> |
| </sect1> |
| |
| <sect1 id="functions-array"> |
| <title>Array Functions and Operators</title> |
| |
| <para> |
| <xref linkend="array-operators-table"/> shows the specialized operators |
| available for array types. |
| In addition to those, the usual comparison operators shown in <xref |
| linkend="functions-comparison-op-table"/> 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 |
| (last subscript varies most rapidly). |
| If the contents of two arrays are equal but the dimensionality is |
| different, the first difference in the dimensionality information |
| determines the sort order. |
| </para> |
| |
| <table id="array-operators-table"> |
| <title>Array Operators</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Operator |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anyarray</type> <literal>@></literal> <type>anyarray</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| 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 <literal>ARRAY[1]</literal> and <literal>ARRAY[1,1]</literal> are |
| each considered to contain the other.) |
| </para> |
| <para> |
| <literal>ARRAY[1,4,3] @> ARRAY[3,1,3]</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anyarray</type> <literal><@</literal> <type>anyarray</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the first array contained by the second? |
| </para> |
| <para> |
| <literal>ARRAY[2,2,7] <@ ARRAY[1,7,4,2,6]</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anyarray</type> <literal>&&</literal> <type>anyarray</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Do the arrays overlap, that is, have any elements in common? |
| </para> |
| <para> |
| <literal>ARRAY[1,4,3] && ARRAY[2,1]</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anycompatiblearray</type> <literal>||</literal> <type>anycompatiblearray</type> |
| <returnvalue>anycompatiblearray</returnvalue> |
| </para> |
| <para> |
| 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). |
| If the arrays are not of identical element types, they will be coerced |
| to a common type (see <xref linkend="typeconv-union-case"/>). |
| </para> |
| <para> |
| <literal>ARRAY[1,2,3] || ARRAY[4,5,6,7]</literal> |
| <returnvalue>{1,2,3,4,5,6,7}</returnvalue> |
| </para> |
| <para> |
| <literal>ARRAY[1,2,3] || ARRAY[[4,5,6],[7,8,9.9]]</literal> |
| <returnvalue>{{1,2,3},{4,5,6},{7,8,9.9}}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anycompatible</type> <literal>||</literal> <type>anycompatiblearray</type> |
| <returnvalue>anycompatiblearray</returnvalue> |
| </para> |
| <para> |
| Concatenates an element onto the front of an array (which must be |
| empty or one-dimensional). |
| </para> |
| <para> |
| <literal>3 || ARRAY[4,5,6]</literal> |
| <returnvalue>{3,4,5,6}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anycompatiblearray</type> <literal>||</literal> <type>anycompatible</type> |
| <returnvalue>anycompatiblearray</returnvalue> |
| </para> |
| <para> |
| Concatenates an element onto the end of an array (which must be |
| empty or one-dimensional). |
| </para> |
| <para> |
| <literal>ARRAY[4,5,6] || 7</literal> |
| <returnvalue>{4,5,6,7}</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| See <xref linkend="arrays"/> for more details about array operator |
| behavior. See <xref linkend="indexes-types"/> for more details about |
| which operators support indexed operations. |
| </para> |
| |
| <para> |
| <xref linkend="array-functions-table"/> shows the functions |
| available for use with array types. See <xref linkend="arrays"/> |
| for more information and examples of the use of these functions. |
| </para> |
| |
| <table id="array-functions-table"> |
| <title>Array Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>array_append</primary> |
| </indexterm> |
| <function>array_append</function> ( <type>anycompatiblearray</type>, <type>anycompatible</type> ) |
| <returnvalue>anycompatiblearray</returnvalue> |
| </para> |
| <para> |
| Appends an element to the end of an array (same as |
| the <type>anycompatiblearray</type> <literal>||</literal> <type>anycompatible</type> |
| operator). |
| </para> |
| <para> |
| <literal>array_append(ARRAY[1,2], 3)</literal> |
| <returnvalue>{1,2,3}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>array_cat</primary> |
| </indexterm> |
| <function>array_cat</function> ( <type>anycompatiblearray</type>, <type>anycompatiblearray</type> ) |
| <returnvalue>anycompatiblearray</returnvalue> |
| </para> |
| <para> |
| Concatenates two arrays (same as |
| the <type>anycompatiblearray</type> <literal>||</literal> <type>anycompatiblearray</type> |
| operator). |
| </para> |
| <para> |
| <literal>array_cat(ARRAY[1,2,3], ARRAY[4,5])</literal> |
| <returnvalue>{1,2,3,4,5}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>array_dims</primary> |
| </indexterm> |
| <function>array_dims</function> ( <type>anyarray</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Returns a text representation of the array's dimensions. |
| </para> |
| <para> |
| <literal>array_dims(ARRAY[[1,2,3], [4,5,6]])</literal> |
| <returnvalue>[1:2][1:3]</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>array_fill</primary> |
| </indexterm> |
| <function>array_fill</function> ( <type>anyelement</type>, <type>integer[]</type> |
| <optional>, <type>integer[]</type> </optional> ) |
| <returnvalue>anyarray</returnvalue> |
| </para> |
| <para> |
| 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 <literal>1</literal>). |
| </para> |
| <para> |
| <literal>array_fill(11, ARRAY[2,3])</literal> |
| <returnvalue>{{11,11,11},{11,11,11}}</returnvalue> |
| </para> |
| <para> |
| <literal>array_fill(7, ARRAY[3], ARRAY[2])</literal> |
| <returnvalue>[2:4]={7,7,7}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>array_length</primary> |
| </indexterm> |
| <function>array_length</function> ( <type>anyarray</type>, <type>integer</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns the length of the requested array dimension. |
| </para> |
| <para> |
| <literal>array_length(array[1,2,3], 1)</literal> |
| <returnvalue>3</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>array_lower</primary> |
| </indexterm> |
| <function>array_lower</function> ( <type>anyarray</type>, <type>integer</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns the lower bound of the requested array dimension. |
| </para> |
| <para> |
| <literal>array_lower('[0:2]={1,2,3}'::integer[], 1)</literal> |
| <returnvalue>0</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>array_ndims</primary> |
| </indexterm> |
| <function>array_ndims</function> ( <type>anyarray</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns the number of dimensions of the array. |
| </para> |
| <para> |
| <literal>array_ndims(ARRAY[[1,2,3], [4,5,6]])</literal> |
| <returnvalue>2</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>array_position</primary> |
| </indexterm> |
| <function>array_position</function> ( <type>anycompatiblearray</type>, <type>anycompatible</type> <optional>, <type>integer</type> </optional> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns the subscript of the first occurrence of the second argument |
| in the array, or <literal>NULL</literal> 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 <literal>IS NOT DISTINCT FROM</literal> |
| semantics, so it is possible to search for <literal>NULL</literal>. |
| </para> |
| <para> |
| <literal>array_position(ARRAY['sun', 'mon', 'tue', 'wed', 'thu', 'fri', 'sat'], 'mon')</literal> |
| <returnvalue>2</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>array_positions</primary> |
| </indexterm> |
| <function>array_positions</function> ( <type>anycompatiblearray</type>, <type>anycompatible</type> ) |
| <returnvalue>integer[]</returnvalue> |
| </para> |
| <para> |
| 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 <literal>IS NOT DISTINCT FROM</literal> |
| semantics, so it is possible to search for <literal>NULL</literal>. |
| <literal>NULL</literal> is returned only if the array |
| is <literal>NULL</literal>; if the value is not found in the array, an |
| empty array is returned. |
| </para> |
| <para> |
| <literal>array_positions(ARRAY['A','A','B','A'], 'A')</literal> |
| <returnvalue>{1,2,4}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>array_prepend</primary> |
| </indexterm> |
| <function>array_prepend</function> ( <type>anycompatible</type>, <type>anycompatiblearray</type> ) |
| <returnvalue>anycompatiblearray</returnvalue> |
| </para> |
| <para> |
| Prepends an element to the beginning of an array (same as |
| the <type>anycompatible</type> <literal>||</literal> <type>anycompatiblearray</type> |
| operator). |
| </para> |
| <para> |
| <literal>array_prepend(1, ARRAY[2,3])</literal> |
| <returnvalue>{1,2,3}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>array_remove</primary> |
| </indexterm> |
| <function>array_remove</function> ( <type>anycompatiblearray</type>, <type>anycompatible</type> ) |
| <returnvalue>anycompatiblearray</returnvalue> |
| </para> |
| <para> |
| Removes all elements equal to the given value from the array. |
| The array must be one-dimensional. |
| Comparisons are done using <literal>IS NOT DISTINCT FROM</literal> |
| semantics, so it is possible to remove <literal>NULL</literal>s. |
| </para> |
| <para> |
| <literal>array_remove(ARRAY[1,2,3,2], 2)</literal> |
| <returnvalue>{1,3}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>array_replace</primary> |
| </indexterm> |
| <function>array_replace</function> ( <type>anycompatiblearray</type>, <type>anycompatible</type>, <type>anycompatible</type> ) |
| <returnvalue>anycompatiblearray</returnvalue> |
| </para> |
| <para> |
| Replaces each array element equal to the second argument with the |
| third argument. |
| </para> |
| <para> |
| <literal>array_replace(ARRAY[1,2,5,4], 5, 3)</literal> |
| <returnvalue>{1,2,3,4}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>array_to_string</primary> |
| </indexterm> |
| <function>array_to_string</function> ( <parameter>array</parameter> <type>anyarray</type>, <parameter>delimiter</parameter> <type>text</type> <optional>, <parameter>null_string</parameter> <type>text</type> </optional> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Converts each array element to its text representation, and |
| concatenates those separated by |
| the <parameter>delimiter</parameter> string. |
| If <parameter>null_string</parameter> is given and is |
| not <literal>NULL</literal>, then <literal>NULL</literal> array |
| entries are represented by that string; otherwise, they are omitted. |
| </para> |
| <para> |
| <literal>array_to_string(ARRAY[1, 2, 3, NULL, 5], ',', '*')</literal> |
| <returnvalue>1,2,3,*,5</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>array_upper</primary> |
| </indexterm> |
| <function>array_upper</function> ( <type>anyarray</type>, <type>integer</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns the upper bound of the requested array dimension. |
| </para> |
| <para> |
| <literal>array_upper(ARRAY[1,8,3,7], 1)</literal> |
| <returnvalue>4</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>cardinality</primary> |
| </indexterm> |
| <function>cardinality</function> ( <type>anyarray</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns the total number of elements in the array, or 0 if the array |
| is empty. |
| </para> |
| <para> |
| <literal>cardinality(ARRAY[[1,2],[3,4]])</literal> |
| <returnvalue>4</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>trim_array</primary> |
| </indexterm> |
| <function>trim_array</function> ( <parameter>array</parameter> <type>anyarray</type>, <parameter>n</parameter> <type>integer</type> ) |
| <returnvalue>anyarray</returnvalue> |
| </para> |
| <para> |
| Trims an array by removing the last <parameter>n</parameter> elements. |
| If the array is multidimensional, only the first dimension is trimmed. |
| </para> |
| <para> |
| <literal>trim_array(ARRAY[1,2,3,4,5,6], 2)</literal> |
| <returnvalue>{1,2,3,4}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>unnest</primary> |
| </indexterm> |
| <function>unnest</function> ( <type>anyarray</type> ) |
| <returnvalue>setof anyelement</returnvalue> |
| </para> |
| <para> |
| Expands an array into a set of rows. |
| The array's elements are read out in storage order. |
| </para> |
| <para> |
| <literal>unnest(ARRAY[1,2])</literal> |
| <returnvalue></returnvalue> |
| <programlisting> |
| 1 |
| 2 |
| </programlisting> |
| </para> |
| <para> |
| <literal>unnest(ARRAY[['foo','bar'],['baz','quux']])</literal> |
| <returnvalue></returnvalue> |
| <programlisting> |
| foo |
| bar |
| baz |
| quux |
| </programlisting> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>unnest</function> ( <type>anyarray</type>, <type>anyarray</type> <optional>, ... </optional> ) |
| <returnvalue>setof anyelement, anyelement [, ... ]</returnvalue> |
| </para> |
| <para> |
| Expands multiple arrays (possibly of different data types) into a set of |
| rows. If the arrays are not all the same length then the shorter ones |
| are padded with <literal>NULL</literal>s. This form is only allowed |
| in a query's FROM clause; see <xref linkend="queries-tablefunctions"/>. |
| </para> |
| <para> |
| <literal>select * from unnest(ARRAY[1,2], ARRAY['foo','bar','baz']) as x(a,b)</literal> |
| <returnvalue></returnvalue> |
| <programlisting> |
| a | b |
| ---+----- |
| 1 | foo |
| 2 | bar |
| | baz |
| </programlisting> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <note> |
| <para> |
| There are two differences in the behavior of <function>string_to_array</function> |
| from pre-9.1 versions of <productname>PostgreSQL</productname>. |
| First, it will return an empty (zero-element) array rather |
| than <literal>NULL</literal> when the input string is of zero length. |
| Second, if the delimiter string is <literal>NULL</literal>, the function |
| splits the input into individual characters, rather than |
| returning <literal>NULL</literal> as before. |
| </para> |
| </note> |
| |
| <para> |
| See also <xref linkend="functions-aggregate"/> about the aggregate |
| function <function>array_agg</function> for use with arrays. |
| </para> |
| </sect1> |
| |
| <sect1 id="functions-range"> |
| <title>Range/Multirange Functions and Operators</title> |
| |
| <para> |
| See <xref linkend="rangetypes"/> for an overview of range types. |
| </para> |
| |
| <para> |
| <xref linkend="range-operators-table"/> shows the specialized operators |
| available for range types. |
| <xref linkend="multirange-operators-table"/> shows the specialized operators |
| available for multirange types. |
| In addition to those, the usual comparison operators shown in |
| <xref linkend="functions-comparison-op-table"/> are available for range |
| and multirange types. The comparison operators order first by the range lower |
| bounds, and only if those are equal do they compare the upper bounds. The |
| multirange operators compare each range until one is unequal. This |
| does not usually result in a useful overall ordering, but the operators are |
| provided to allow unique indexes to be constructed on ranges. |
| </para> |
| |
| <table id="range-operators-table"> |
| <title>Range Operators</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Operator |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anyrange</type> <literal>@></literal> <type>anyrange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does the first range contain the second? |
| </para> |
| <para> |
| <literal>int4range(2,4) @> int4range(2,3)</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anyrange</type> <literal>@></literal> <type>anyelement</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does the range contain the element? |
| </para> |
| <para> |
| <literal>'[2011-01-01,2011-03-01)'::tsrange @> '2011-01-10'::timestamp</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anyrange</type> <literal><@</literal> <type>anyrange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the first range contained by the second? |
| </para> |
| <para> |
| <literal>int4range(2,4) <@ int4range(1,7)</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anyelement</type> <literal><@</literal> <type>anyrange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the element contained in the range? |
| </para> |
| <para> |
| <literal>42 <@ int4range(1,7)</literal> |
| <returnvalue>f</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anyrange</type> <literal>&&</literal> <type>anyrange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Do the ranges overlap, that is, have any elements in common? |
| </para> |
| <para> |
| <literal>int8range(3,7) && int8range(4,12)</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anyrange</type> <literal><<</literal> <type>anyrange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the first range strictly left of the second? |
| </para> |
| <para> |
| <literal>int8range(1,10) << int8range(100,110)</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anyrange</type> <literal>>></literal> <type>anyrange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the first range strictly right of the second? |
| </para> |
| <para> |
| <literal>int8range(50,60) >> int8range(20,30)</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anyrange</type> <literal>&<</literal> <type>anyrange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does the first range not extend to the right of the second? |
| </para> |
| <para> |
| <literal>int8range(1,20) &< int8range(18,20)</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anyrange</type> <literal>&></literal> <type>anyrange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does the first range not extend to the left of the second? |
| </para> |
| <para> |
| <literal>int8range(7,20) &> int8range(5,10)</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anyrange</type> <literal>-|-</literal> <type>anyrange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Are the ranges adjacent? |
| </para> |
| <para> |
| <literal>numrange(1.1,2.2) -|- numrange(2.2,3.3)</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anyrange</type> <literal>+</literal> <type>anyrange</type> |
| <returnvalue>anyrange</returnvalue> |
| </para> |
| <para> |
| Computes the union of the ranges. The ranges must overlap or be |
| adjacent, so that the union is a single range (but |
| see <function>range_merge()</function>). |
| </para> |
| <para> |
| <literal>numrange(5,15) + numrange(10,20)</literal> |
| <returnvalue>[5,20)</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anyrange</type> <literal>*</literal> <type>anyrange</type> |
| <returnvalue>anyrange</returnvalue> |
| </para> |
| <para> |
| Computes the intersection of the ranges. |
| </para> |
| <para> |
| <literal>int8range(5,15) * int8range(10,20)</literal> |
| <returnvalue>[10,15)</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anyrange</type> <literal>-</literal> <type>anyrange</type> |
| <returnvalue>anyrange</returnvalue> |
| </para> |
| <para> |
| 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. |
| </para> |
| <para> |
| <literal>int8range(5,15) - int8range(10,20)</literal> |
| <returnvalue>[5,10)</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <table id="multirange-operators-table"> |
| <title>Multirange Operators</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Operator |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anymultirange</type> <literal>@></literal> <type>anymultirange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does the first multirange contain the second? |
| </para> |
| <para> |
| <literal>'{[2,4)}'::int4multirange @> '{[2,3)}'::int4multirange</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anymultirange</type> <literal>@></literal> <type>anyrange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does the multirange contain the range? |
| </para> |
| <para> |
| <literal>'{[2,4)}'::int4multirange @> int4range(2,3)</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anymultirange</type> <literal>@></literal> <type>anyelement</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does the multirange contain the element? |
| </para> |
| <para> |
| <literal>'{[2011-01-01,2011-03-01)}'::tsmultirange @> '2011-01-10'::timestamp</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anyrange</type> <literal>@></literal> <type>anymultirange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does the range contain the multirange? |
| </para> |
| <para> |
| <literal>'[2,4)'::int4range @> '{[2,3)}'::int4multirange</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anymultirange</type> <literal><@</literal> <type>anymultirange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the first multirange contained by the second? |
| </para> |
| <para> |
| <literal>'{[2,4)}'::int4multirange <@ '{[1,7)}'::int4multirange</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anymultirange</type> <literal><@</literal> <type>anyrange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the multirange contained by the range? |
| </para> |
| <para> |
| <literal>'{[2,4)}'::int4multirange <@ int4range(1,7)</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anyrange</type> <literal><@</literal> <type>anymultirange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the range contained by the multirange? |
| </para> |
| <para> |
| <literal>int4range(2,4) <@ '{[1,7)}'::int4multirange</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anyelement</type> <literal><@</literal> <type>anymultirange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the element contained by the multirange? |
| </para> |
| <para> |
| <literal>4 <@ '{[1,7)}'::int4multirange</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anymultirange</type> <literal>&&</literal> <type>anymultirange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Do the multiranges overlap, that is, have any elements in common? |
| </para> |
| <para> |
| <literal>'{[3,7)}'::int8multirange && '{[4,12)}'::int8multirange</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anymultirange</type> <literal>&&</literal> <type>anyrange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does the multirange overlap the range? |
| </para> |
| <para> |
| <literal>'{[3,7)}'::int8multirange && int8range(4,12)</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anyrange</type> <literal>&&</literal> <type>anymultirange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does the range overlap the multirange? |
| </para> |
| <para> |
| <literal>int8range(3,7) && '{[4,12)}'::int8multirange</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anymultirange</type> <literal><<</literal> <type>anymultirange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the first multirange strictly left of the second? |
| </para> |
| <para> |
| <literal>'{[1,10)}'::int8multirange << '{[100,110)}'::int8multirange</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anymultirange</type> <literal><<</literal> <type>anyrange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the multirange strictly left of the range? |
| </para> |
| <para> |
| <literal>'{[1,10)}'::int8multirange << int8range(100,110)</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anyrange</type> <literal><<</literal> <type>anymultirange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the range strictly left of the multirange? |
| </para> |
| <para> |
| <literal>int8range(1,10) << '{[100,110)}'::int8multirange</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anymultirange</type> <literal>>></literal> <type>anymultirange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the first multirange strictly right of the second? |
| </para> |
| <para> |
| <literal>'{[50,60)}'::int8multirange >> '{[20,30)}'::int8multirange</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anymultirange</type> <literal>>></literal> <type>anyrange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the multirange strictly right of the range? |
| </para> |
| <para> |
| <literal>'{[50,60)}'::int8multirange >> int8range(20,30)</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anyrange</type> <literal>>></literal> <type>anymultirange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the range strictly right of the multirange? |
| </para> |
| <para> |
| <literal>int8range(50,60) >> '{[20,30)}'::int8multirange</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anymultirange</type> <literal>&<</literal> <type>anymultirange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does the first multirange not extend to the right of the second? |
| </para> |
| <para> |
| <literal>'{[1,20)}'::int8multirange &< '{[18,20)}'::int8multirange</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anymultirange</type> <literal>&<</literal> <type>anyrange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does the multirange not extend to the right of the range? |
| </para> |
| <para> |
| <literal>'{[1,20)}'::int8multirange &< int8range(18,20)</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anyrange</type> <literal>&<</literal> <type>anymultirange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does the range not extend to the right of the multirange? |
| </para> |
| <para> |
| <literal>int8range(1,20) &< '{[18,20)}'::int8multirange</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anymultirange</type> <literal>&></literal> <type>anymultirange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does the first multirange not extend to the left of the second? |
| </para> |
| <para> |
| <literal>'{[7,20)}'::int8multirange &> '{[5,10)}'::int8multirange</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anymultirange</type> <literal>&></literal> <type>anyrange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does the multirange not extend to the left of the range? |
| </para> |
| <para> |
| <literal>'{[7,20)}'::int8multirange &> int8range(5,10)</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anyrange</type> <literal>&></literal> <type>anymultirange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does the range not extend to the left of the multirange? |
| </para> |
| <para> |
| <literal>int8range(7,20) &> '{[5,10)}'::int8multirange</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anymultirange</type> <literal>-|-</literal> <type>anymultirange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Are the multiranges adjacent? |
| </para> |
| <para> |
| <literal>'{[1.1,2.2)}'::nummultirange -|- '{[2.2,3.3)}'::nummultirange</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anymultirange</type> <literal>-|-</literal> <type>anyrange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the multirange adjacent to the range? |
| </para> |
| <para> |
| <literal>'{[1.1,2.2)}'::nummultirange -|- numrange(2.2,3.3)</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anyrange</type> <literal>-|-</literal> <type>anymultirange</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the range adjacent to the multirange? |
| </para> |
| <para> |
| <literal>numrange(1.1,2.2) -|- '{[2.2,3.3)}'::nummultirange</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anymultirange</type> <literal>+</literal> <type>anymultirange</type> |
| <returnvalue>anymultirange</returnvalue> |
| </para> |
| <para> |
| Computes the union of the multiranges. The multiranges need not overlap |
| or be adjacent. |
| </para> |
| <para> |
| <literal>'{[5,10)}'::nummultirange + '{[15,20)}'::nummultirange</literal> |
| <returnvalue>{[5,10), [15,20)}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anymultirange</type> <literal>*</literal> <type>anymultirange</type> |
| <returnvalue>anymultirange</returnvalue> |
| </para> |
| <para> |
| Computes the intersection of the multiranges. |
| </para> |
| <para> |
| <literal>'{[5,15)}'::int8multirange * '{[10,20)}'::int8multirange</literal> |
| <returnvalue>{[10,15)}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>anymultirange</type> <literal>-</literal> <type>anymultirange</type> |
| <returnvalue>anymultirange</returnvalue> |
| </para> |
| <para> |
| Computes the difference of the multiranges. |
| </para> |
| <para> |
| <literal>'{[5,20)}'::int8multirange - '{[10,15)}'::int8multirange</literal> |
| <returnvalue>{[5,10), [15,20)}</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| The left-of/right-of/adjacent operators always return false when an empty |
| range or multirange is involved; that is, an empty range is not considered to |
| be either before or after any other range. |
| </para> |
| |
| <para> |
| Elsewhere empty ranges and multiranges are treated as the additive identity: |
| anything unioned with an empty value is itself. Anything minus an empty |
| value is itself. An empty multirange has exactly the same points as an empty |
| range. Every range contains the empty range. Every multirange contains as many |
| empty ranges as you like. |
| </para> |
| |
| <para> |
| The range 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. There are separate operators for union and difference that take |
| multirange parameters and return a multirange, and they do not fail even if |
| their arguments are disjoint. So if you need a union or difference operation |
| for ranges that may be disjoint, you can avoid errors by first casting your |
| ranges to multiranges. |
| </para> |
| |
| <para> |
| <xref linkend="range-functions-table"/> shows the functions |
| available for use with range types. |
| <xref linkend="multirange-functions-table"/> shows the functions |
| available for use with multirange types. |
| </para> |
| |
| <table id="range-functions-table"> |
| <title>Range Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>lower</primary> |
| </indexterm> |
| <function>lower</function> ( <type>anyrange</type> ) |
| <returnvalue>anyelement</returnvalue> |
| </para> |
| <para> |
| Extracts the lower bound of the range (<literal>NULL</literal> if the |
| range is empty or the lower bound is infinite). |
| </para> |
| <para> |
| <literal>lower(numrange(1.1,2.2))</literal> |
| <returnvalue>1.1</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>upper</primary> |
| </indexterm> |
| <function>upper</function> ( <type>anyrange</type> ) |
| <returnvalue>anyelement</returnvalue> |
| </para> |
| <para> |
| Extracts the upper bound of the range (<literal>NULL</literal> if the |
| range is empty or the upper bound is infinite). |
| </para> |
| <para> |
| <literal>upper(numrange(1.1,2.2))</literal> |
| <returnvalue>2.2</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>isempty</primary> |
| </indexterm> |
| <function>isempty</function> ( <type>anyrange</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the range empty? |
| </para> |
| <para> |
| <literal>isempty(numrange(1.1,2.2))</literal> |
| <returnvalue>f</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>lower_inc</primary> |
| </indexterm> |
| <function>lower_inc</function> ( <type>anyrange</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the range's lower bound inclusive? |
| </para> |
| <para> |
| <literal>lower_inc(numrange(1.1,2.2))</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>upper_inc</primary> |
| </indexterm> |
| <function>upper_inc</function> ( <type>anyrange</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the range's upper bound inclusive? |
| </para> |
| <para> |
| <literal>upper_inc(numrange(1.1,2.2))</literal> |
| <returnvalue>f</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>lower_inf</primary> |
| </indexterm> |
| <function>lower_inf</function> ( <type>anyrange</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the range's lower bound infinite? |
| </para> |
| <para> |
| <literal>lower_inf('(,)'::daterange)</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>upper_inf</primary> |
| </indexterm> |
| <function>upper_inf</function> ( <type>anyrange</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the range's upper bound infinite? |
| </para> |
| <para> |
| <literal>upper_inf('(,)'::daterange)</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>range_merge</primary> |
| </indexterm> |
| <function>range_merge</function> ( <type>anyrange</type>, <type>anyrange</type> ) |
| <returnvalue>anyrange</returnvalue> |
| </para> |
| <para> |
| Computes the smallest range that includes both of the given ranges. |
| </para> |
| <para> |
| <literal>range_merge('[1,2)'::int4range, '[3,4)'::int4range)</literal> |
| <returnvalue>[1,4)</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <table id="multirange-functions-table"> |
| <title>Multirange Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>lower</primary> |
| </indexterm> |
| <function>lower</function> ( <type>anymultirange</type> ) |
| <returnvalue>anyelement</returnvalue> |
| </para> |
| <para> |
| Extracts the lower bound of the multirange (<literal>NULL</literal> if the |
| multirange is empty or the lower bound is infinite). |
| </para> |
| <para> |
| <literal>lower('{[1.1,2.2)}'::nummultirange)</literal> |
| <returnvalue>1.1</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>upper</primary> |
| </indexterm> |
| <function>upper</function> ( <type>anymultirange</type> ) |
| <returnvalue>anyelement</returnvalue> |
| </para> |
| <para> |
| Extracts the upper bound of the multirange (<literal>NULL</literal> if the |
| multirange is empty or the upper bound is infinite). |
| </para> |
| <para> |
| <literal>upper('{[1.1,2.2)}'::nummultirange)</literal> |
| <returnvalue>2.2</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>isempty</primary> |
| </indexterm> |
| <function>isempty</function> ( <type>anymultirange</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the multirange empty? |
| </para> |
| <para> |
| <literal>isempty('{[1.1,2.2)}'::nummultirange)</literal> |
| <returnvalue>f</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>lower_inc</primary> |
| </indexterm> |
| <function>lower_inc</function> ( <type>anymultirange</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the multirange's lower bound inclusive? |
| </para> |
| <para> |
| <literal>lower_inc('{[1.1,2.2)}'::nummultirange)</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>upper_inc</primary> |
| </indexterm> |
| <function>upper_inc</function> ( <type>anymultirange</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the multirange's upper bound inclusive? |
| </para> |
| <para> |
| <literal>upper_inc('{[1.1,2.2)}'::nummultirange)</literal> |
| <returnvalue>f</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>lower_inf</primary> |
| </indexterm> |
| <function>lower_inf</function> ( <type>anymultirange</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the multirange's lower bound infinite? |
| </para> |
| <para> |
| <literal>lower_inf('{(,)}'::datemultirange)</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>upper_inf</primary> |
| </indexterm> |
| <function>upper_inf</function> ( <type>anymultirange</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the multirange's upper bound infinite? |
| </para> |
| <para> |
| <literal>upper_inf('{(,)}'::datemultirange)</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>range_merge</primary> |
| </indexterm> |
| <function>range_merge</function> ( <type>anymultirange</type> ) |
| <returnvalue>anyrange</returnvalue> |
| </para> |
| <para> |
| Computes the smallest range that includes the entire multirange. |
| </para> |
| <para> |
| <literal>range_merge('{[1,2), [3,4)}'::int4multirange)</literal> |
| <returnvalue>[1,4)</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>multirange (function)</primary> |
| </indexterm> |
| <function>multirange</function> ( <type>anyrange</type> ) |
| <returnvalue>anymultirange</returnvalue> |
| </para> |
| <para> |
| Returns a multirange containing just the given range. |
| </para> |
| <para> |
| <literal>multirange('[1,2)'::int4range)</literal> |
| <returnvalue>{[1,2)}</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>unnest</primary> |
| <secondary>for multirange</secondary> |
| </indexterm> |
| <function>unnest</function> ( <type>anymultirange</type> ) |
| <returnvalue>setof anyrange</returnvalue> |
| </para> |
| <para> |
| Expands a multirange into a set of ranges. |
| The ranges are read out in storage order (ascending). |
| </para> |
| <para> |
| <literal>unnest('{[1,2), [3,4)}'::int4multirange)</literal> |
| <returnvalue></returnvalue> |
| <programlisting> |
| [1,2) |
| [3,4) |
| </programlisting> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| The <function>lower_inc</function>, <function>upper_inc</function>, |
| <function>lower_inf</function>, and <function>upper_inf</function> |
| functions all return false for an empty range or multirange. |
| </para> |
| </sect1> |
| |
| <sect1 id="functions-aggregate"> |
| <title>Aggregate Functions</title> |
| |
| <indexterm zone="functions-aggregate"> |
| <primary>aggregate function</primary> |
| <secondary>built-in</secondary> |
| </indexterm> |
| |
| <para> |
| <firstterm>Aggregate functions</firstterm> compute a single result |
| from a set of input values. The built-in general-purpose aggregate |
| functions are listed in <xref linkend="functions-aggregate-table"/> |
| while statistical aggregates are in <xref |
| linkend="functions-aggregate-statistics-table"/>. |
| The built-in within-group ordered-set aggregate functions |
| are listed in <xref linkend="functions-orderedset-table"/> |
| while the built-in within-group hypothetical-set ones are in <xref |
| linkend="functions-hypothetical-table"/>. Grouping operations, |
| which are closely related to aggregate functions, are listed in |
| <xref linkend="functions-grouping-table"/>. |
| The special syntax considerations for aggregate |
| functions are explained in <xref linkend="syntax-aggregates"/>. |
| Consult <xref linkend="tutorial-agg"/> for additional introductory |
| information. |
| </para> |
| |
| <para> |
| Aggregate functions that support <firstterm>Partial Mode</firstterm> |
| are eligible to participate in various optimizations, such as parallel |
| aggregation. |
| </para> |
| |
| <table id="functions-aggregate-table"> |
| <title>General-Purpose Aggregate Functions</title> |
| <tgroup cols="2"> |
| <colspec colname="col1" colwidth="10*"/> |
| <colspec colname="col2" colwidth="1*"/> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| <entry>Partial Mode</entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>array_agg</primary> |
| </indexterm> |
| <function>array_agg</function> ( <type>anynonarray</type> ) |
| <returnvalue>anyarray</returnvalue> |
| </para> |
| <para> |
| Collects all the input values, including nulls, into an array. |
| </para></entry> |
| <entry>No</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>array_agg</function> ( <type>anyarray</type> ) |
| <returnvalue>anyarray</returnvalue> |
| </para> |
| <para> |
| 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.) |
| </para></entry> |
| <entry>No</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>average</primary> |
| </indexterm> |
| <indexterm> |
| <primary>avg</primary> |
| </indexterm> |
| <function>avg</function> ( <type>smallint</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>avg</function> ( <type>integer</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>avg</function> ( <type>bigint</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>avg</function> ( <type>numeric</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>avg</function> ( <type>real</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>avg</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>avg</function> ( <type>interval</type> ) |
| <returnvalue>interval</returnvalue> |
| </para> |
| <para> |
| Computes the average (arithmetic mean) of all the non-null input |
| values. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>bit_and</primary> |
| </indexterm> |
| <function>bit_and</function> ( <type>smallint</type> ) |
| <returnvalue>smallint</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>bit_and</function> ( <type>integer</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>bit_and</function> ( <type>bigint</type> ) |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>bit_and</function> ( <type>bit</type> ) |
| <returnvalue>bit</returnvalue> |
| </para> |
| <para> |
| Computes the bitwise AND of all non-null input values. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>bit_or</primary> |
| </indexterm> |
| <function>bit_or</function> ( <type>smallint</type> ) |
| <returnvalue>smallint</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>bit_or</function> ( <type>integer</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>bit_or</function> ( <type>bigint</type> ) |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>bit_or</function> ( <type>bit</type> ) |
| <returnvalue>bit</returnvalue> |
| </para> |
| <para> |
| Computes the bitwise OR of all non-null input values. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>bit_xor</primary> |
| </indexterm> |
| <function>bit_xor</function> ( <type>smallint</type> ) |
| <returnvalue>smallint</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>bit_xor</function> ( <type>integer</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>bit_xor</function> ( <type>bigint</type> ) |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>bit_xor</function> ( <type>bit</type> ) |
| <returnvalue>bit</returnvalue> |
| </para> |
| <para> |
| Computes the bitwise exclusive OR of all non-null input values. |
| Can be useful as a checksum for an unordered set of values. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>bool_and</primary> |
| </indexterm> |
| <function>bool_and</function> ( <type>boolean</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Returns true if all non-null input values are true, otherwise false. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>bool_or</primary> |
| </indexterm> |
| <function>bool_or</function> ( <type>boolean</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Returns true if any non-null input value is true, otherwise false. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>count</primary> |
| </indexterm> |
| <function>count</function> ( <literal>*</literal> ) |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para> |
| Computes the number of input rows. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>count</function> ( <type>"any"</type> ) |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para> |
| Computes the number of input rows in which the input value is not |
| null. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>every</primary> |
| </indexterm> |
| <function>every</function> ( <type>boolean</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| This is the SQL standard's equivalent to <function>bool_and</function>. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>json_agg</primary> |
| </indexterm> |
| <function>json_agg</function> ( <type>anyelement</type> ) |
| <returnvalue>json</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_agg</primary> |
| </indexterm> |
| <function>jsonb_agg</function> ( <type>anyelement</type> ) |
| <returnvalue>jsonb</returnvalue> |
| </para> |
| <para> |
| Collects all the input values, including nulls, into a JSON array. |
| Values are converted to JSON as per <function>to_json</function> |
| or <function>to_jsonb</function>. |
| </para></entry> |
| <entry>No</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>json_object_agg</primary> |
| </indexterm> |
| <function>json_object_agg</function> ( <parameter>key</parameter> |
| <type>"any"</type>, <parameter>value</parameter> |
| <type>"any"</type> ) |
| <returnvalue>json</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <indexterm> |
| <primary>jsonb_object_agg</primary> |
| </indexterm> |
| <function>jsonb_object_agg</function> ( <parameter>key</parameter> |
| <type>"any"</type>, <parameter>value</parameter> |
| <type>"any"</type> ) |
| <returnvalue>jsonb</returnvalue> |
| </para> |
| <para> |
| Collects all the key/value pairs into a JSON object. Key arguments |
| are coerced to text; value arguments are converted as |
| per <function>to_json</function> or <function>to_jsonb</function>. |
| Values can be null, but not keys. |
| </para></entry> |
| <entry>No</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>max</primary> |
| </indexterm> |
| <function>max</function> ( <replaceable>see text</replaceable> ) |
| <returnvalue><replaceable>same as input type</replaceable></returnvalue> |
| </para> |
| <para> |
| Computes the maximum of the non-null input |
| values. Available for any numeric, string, date/time, or enum type, |
| as well as <type>inet</type>, <type>interval</type>, |
| <type>money</type>, <type>oid</type>, <type>pg_lsn</type>, |
| <type>tid</type>, |
| and arrays of any of these types. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>min</primary> |
| </indexterm> |
| <function>min</function> ( <replaceable>see text</replaceable> ) |
| <returnvalue><replaceable>same as input type</replaceable></returnvalue> |
| </para> |
| <para> |
| Computes the minimum of the non-null input |
| values. Available for any numeric, string, date/time, or enum type, |
| as well as <type>inet</type>, <type>interval</type>, |
| <type>money</type>, <type>oid</type>, <type>pg_lsn</type>, |
| <type>tid</type>, |
| and arrays of any of these types. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>range_agg</primary> |
| </indexterm> |
| <function>range_agg</function> ( <parameter>value</parameter> |
| <type>anyrange</type> ) |
| <returnvalue>anymultirange</returnvalue> |
| </para> |
| <para> |
| Computes the union of the non-null input values. |
| </para></entry> |
| <entry>No</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>range_intersect_agg</primary> |
| </indexterm> |
| <function>range_intersect_agg</function> ( <parameter>value</parameter> |
| <type>anyrange</type> ) |
| <returnvalue>anyrange</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>range_intersect_agg</function> ( <parameter>value</parameter> |
| <type>anymultirange</type> ) |
| <returnvalue>anymultirange</returnvalue> |
| </para> |
| <para> |
| Computes the intersection of the non-null input values. |
| </para></entry> |
| <entry>No</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>string_agg</primary> |
| </indexterm> |
| <function>string_agg</function> ( <parameter>value</parameter> |
| <type>text</type>, <parameter>delimiter</parameter> <type>text</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>string_agg</function> ( <parameter>value</parameter> |
| <type>bytea</type>, <parameter>delimiter</parameter> <type>bytea</type> ) |
| <returnvalue>bytea</returnvalue> |
| </para> |
| <para> |
| Concatenates the non-null input values into a string. Each value |
| after the first is preceded by the |
| corresponding <parameter>delimiter</parameter> (if it's not null). |
| </para></entry> |
| <entry>No</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>sum</primary> |
| </indexterm> |
| <function>sum</function> ( <type>smallint</type> ) |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>sum</function> ( <type>integer</type> ) |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>sum</function> ( <type>bigint</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>sum</function> ( <type>numeric</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>sum</function> ( <type>real</type> ) |
| <returnvalue>real</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>sum</function> ( <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>sum</function> ( <type>interval</type> ) |
| <returnvalue>interval</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>sum</function> ( <type>money</type> ) |
| <returnvalue>money</returnvalue> |
| </para> |
| <para> |
| Computes the sum of the non-null input values. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>xmlagg</primary> |
| </indexterm> |
| <function>xmlagg</function> ( <type>xml</type> ) |
| <returnvalue>xml</returnvalue> |
| </para> |
| <para> |
| Concatenates the non-null XML input values (see |
| <xref linkend="functions-xml-xmlagg"/>). |
| </para></entry> |
| <entry>No</entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| It should be noted that except for <function>count</function>, |
| these functions return a null value when no rows are selected. In |
| particular, <function>sum</function> of no rows returns null, not |
| zero as one might expect, and <function>array_agg</function> |
| returns null rather than an empty array when there are no input |
| rows. The <function>coalesce</function> function can be used to |
| substitute zero or an empty array for null when necessary. |
| </para> |
| |
| <para> |
| The aggregate functions <function>array_agg</function>, |
| <function>json_agg</function>, <function>jsonb_agg</function>, |
| <function>json_object_agg</function>, <function>jsonb_object_agg</function>, |
| <function>string_agg</function>, |
| and <function>xmlagg</function>, as well as similar user-defined |
| aggregate functions, produce meaningfully different result values |
| depending on the order of the input values. This ordering is |
| unspecified by default, but can be controlled by writing an |
| <literal>ORDER BY</literal> clause within the aggregate call, as shown in |
| <xref linkend="syntax-aggregates"/>. |
| Alternatively, supplying the input values from a sorted subquery |
| will usually work. For example: |
| |
| <screen><![CDATA[ |
| SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab; |
| ]]></screen> |
| |
| Beware that this approach can fail if the outer query level contains |
| additional processing, such as a join, because that might cause the |
| subquery's output to be reordered before the aggregate is computed. |
| </para> |
| |
| <note> |
| <indexterm> |
| <primary>ANY</primary> |
| </indexterm> |
| <indexterm> |
| <primary>SOME</primary> |
| </indexterm> |
| <para> |
| The boolean aggregates <function>bool_and</function> and |
| <function>bool_or</function> correspond to the standard SQL aggregates |
| <function>every</function> and <function>any</function> or |
| <function>some</function>. |
| <productname>PostgreSQL</productname> |
| supports <function>every</function>, but not <function>any</function> |
| or <function>some</function>, because there is an ambiguity built into |
| the standard syntax: |
| <programlisting> |
| SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...; |
| </programlisting> |
| Here <function>ANY</function> 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. |
| </para> |
| </note> |
| |
| <note> |
| <para> |
| Users accustomed to working with other SQL database management |
| systems might be disappointed by the performance of the |
| <function>count</function> aggregate when it is applied to the |
| entire table. A query like: |
| <programlisting> |
| SELECT count(*) FROM sometable; |
| </programlisting> |
| will require effort proportional to the size of the table: |
| <productname>PostgreSQL</productname> will need to scan either the |
| entire table or the entirety of an index that includes all rows in |
| the table. |
| </para> |
| </note> |
| |
| <para> |
| <xref linkend="functions-aggregate-statistics-table"/> shows |
| aggregate functions typically used in statistical analysis. |
| (These are separated out merely to avoid cluttering the listing |
| of more-commonly-used aggregates.) Functions shown as |
| accepting <replaceable>numeric_type</replaceable> are available for all |
| the types <type>smallint</type>, <type>integer</type>, |
| <type>bigint</type>, <type>numeric</type>, <type>real</type>, |
| and <type>double precision</type>. |
| Where the description mentions |
| <parameter>N</parameter>, 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, |
| for example when <parameter>N</parameter> is zero. |
| </para> |
| |
| <indexterm> |
| <primary>statistics</primary> |
| </indexterm> |
| <indexterm> |
| <primary>linear regression</primary> |
| </indexterm> |
| |
| <table id="functions-aggregate-statistics-table"> |
| <title>Aggregate Functions for Statistics</title> |
| <tgroup cols="2"> |
| <colspec colname="col1" colwidth="10*"/> |
| <colspec colname="col2" colwidth="1*"/> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| <entry>Partial Mode</entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>correlation</primary> |
| </indexterm> |
| <indexterm> |
| <primary>corr</primary> |
| </indexterm> |
| <function>corr</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Computes the correlation coefficient. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>covariance</primary> |
| <secondary>population</secondary> |
| </indexterm> |
| <indexterm> |
| <primary>covar_pop</primary> |
| </indexterm> |
| <function>covar_pop</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Computes the population covariance. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>covariance</primary> |
| <secondary>sample</secondary> |
| </indexterm> |
| <indexterm> |
| <primary>covar_samp</primary> |
| </indexterm> |
| <function>covar_samp</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Computes the sample covariance. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>regr_avgx</primary> |
| </indexterm> |
| <function>regr_avgx</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Computes the average of the independent variable, |
| <literal>sum(<parameter>X</parameter>)/<parameter>N</parameter></literal>. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>regr_avgy</primary> |
| </indexterm> |
| <function>regr_avgy</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Computes the average of the dependent variable, |
| <literal>sum(<parameter>Y</parameter>)/<parameter>N</parameter></literal>. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>regr_count</primary> |
| </indexterm> |
| <function>regr_count</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> ) |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para> |
| Computes the number of rows in which both inputs are non-null. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>regression intercept</primary> |
| </indexterm> |
| <indexterm> |
| <primary>regr_intercept</primary> |
| </indexterm> |
| <function>regr_intercept</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Computes the y-intercept of the least-squares-fit linear equation |
| determined by the |
| (<parameter>X</parameter>, <parameter>Y</parameter>) pairs. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>regr_r2</primary> |
| </indexterm> |
| <function>regr_r2</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Computes the square of the correlation coefficient. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>regression slope</primary> |
| </indexterm> |
| <indexterm> |
| <primary>regr_slope</primary> |
| </indexterm> |
| <function>regr_slope</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Computes the slope of the least-squares-fit linear equation determined |
| by the (<parameter>X</parameter>, <parameter>Y</parameter>) |
| pairs. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>regr_sxx</primary> |
| </indexterm> |
| <function>regr_sxx</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Computes the <quote>sum of squares</quote> of the independent |
| variable, |
| <literal>sum(<parameter>X</parameter>^2) - sum(<parameter>X</parameter>)^2/<parameter>N</parameter></literal>. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>regr_sxy</primary> |
| </indexterm> |
| <function>regr_sxy</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Computes the <quote>sum of products</quote> of independent times |
| dependent variables, |
| <literal>sum(<parameter>X</parameter>*<parameter>Y</parameter>) - sum(<parameter>X</parameter>) * sum(<parameter>Y</parameter>)/<parameter>N</parameter></literal>. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>regr_syy</primary> |
| </indexterm> |
| <function>regr_syy</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Computes the <quote>sum of squares</quote> of the dependent |
| variable, |
| <literal>sum(<parameter>Y</parameter>^2) - sum(<parameter>Y</parameter>)^2/<parameter>N</parameter></literal>. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>standard deviation</primary> |
| </indexterm> |
| <indexterm> |
| <primary>stddev</primary> |
| </indexterm> |
| <function>stddev</function> ( <replaceable>numeric_type</replaceable> ) |
| <returnvalue></returnvalue> <type>double precision</type> |
| for <type>real</type> or <type>double precision</type>, |
| otherwise <type>numeric</type> |
| </para> |
| <para> |
| This is a historical alias for <function>stddev_samp</function>. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>standard deviation</primary> |
| <secondary>population</secondary> |
| </indexterm> |
| <indexterm> |
| <primary>stddev_pop</primary> |
| </indexterm> |
| <function>stddev_pop</function> ( <replaceable>numeric_type</replaceable> ) |
| <returnvalue></returnvalue> <type>double precision</type> |
| for <type>real</type> or <type>double precision</type>, |
| otherwise <type>numeric</type> |
| </para> |
| <para> |
| Computes the population standard deviation of the input values. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>standard deviation</primary> |
| <secondary>sample</secondary> |
| </indexterm> |
| <indexterm> |
| <primary>stddev_samp</primary> |
| </indexterm> |
| <function>stddev_samp</function> ( <replaceable>numeric_type</replaceable> ) |
| <returnvalue></returnvalue> <type>double precision</type> |
| for <type>real</type> or <type>double precision</type>, |
| otherwise <type>numeric</type> |
| </para> |
| <para> |
| Computes the sample standard deviation of the input values. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>variance</primary> |
| </indexterm> |
| <function>variance</function> ( <replaceable>numeric_type</replaceable> ) |
| <returnvalue></returnvalue> <type>double precision</type> |
| for <type>real</type> or <type>double precision</type>, |
| otherwise <type>numeric</type> |
| </para> |
| <para> |
| This is a historical alias for <function>var_samp</function>. |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>variance</primary> |
| <secondary>population</secondary> |
| </indexterm> |
| <indexterm> |
| <primary>var_pop</primary> |
| </indexterm> |
| <function>var_pop</function> ( <replaceable>numeric_type</replaceable> ) |
| <returnvalue></returnvalue> <type>double precision</type> |
| for <type>real</type> or <type>double precision</type>, |
| otherwise <type>numeric</type> |
| </para> |
| <para> |
| Computes the population variance of the input values (square of the |
| population standard deviation). |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>variance</primary> |
| <secondary>sample</secondary> |
| </indexterm> |
| <indexterm> |
| <primary>var_samp</primary> |
| </indexterm> |
| <function>var_samp</function> ( <replaceable>numeric_type</replaceable> ) |
| <returnvalue></returnvalue> <type>double precision</type> |
| for <type>real</type> or <type>double precision</type>, |
| otherwise <type>numeric</type> |
| </para> |
| <para> |
| Computes the sample variance of the input values (square of the sample |
| standard deviation). |
| </para></entry> |
| <entry>Yes</entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| <xref linkend="functions-orderedset-table"/> shows some |
| aggregate functions that use the <firstterm>ordered-set aggregate</firstterm> |
| syntax. These functions are sometimes referred to as <quote>inverse |
| distribution</quote> functions. Their aggregated input is introduced by |
| <literal>ORDER BY</literal>, and they may also take a <firstterm>direct |
| argument</firstterm> that is not aggregated, but is computed only once. |
| All these functions ignore null values in their aggregated input. |
| For those that take a <parameter>fraction</parameter> parameter, the |
| fraction value must be between 0 and 1; an error is thrown if not. |
| However, a null <parameter>fraction</parameter> value simply produces a |
| null result. |
| </para> |
| |
| <indexterm> |
| <primary>ordered-set aggregate</primary> |
| <secondary>built-in</secondary> |
| </indexterm> |
| <indexterm> |
| <primary>inverse distribution</primary> |
| </indexterm> |
| |
| <table id="functions-orderedset-table"> |
| <title>Ordered-Set Aggregate Functions</title> |
| <tgroup cols="2"> |
| <colspec colname="col1" colwidth="10*"/> |
| <colspec colname="col2" colwidth="1*"/> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| <entry>Partial Mode</entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>mode</primary> |
| <secondary>statistical</secondary> |
| </indexterm> |
| <function>mode</function> () <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>anyelement</type> ) |
| <returnvalue>anyelement</returnvalue> |
| </para> |
| <para> |
| Computes the <firstterm>mode</firstterm>, 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. |
| </para></entry> |
| <entry>No</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>percentile</primary> |
| <secondary>continuous</secondary> |
| </indexterm> |
| <function>percentile_cont</function> ( <parameter>fraction</parameter> <type>double precision</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>double precision</type> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>percentile_cont</function> ( <parameter>fraction</parameter> <type>double precision</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>interval</type> ) |
| <returnvalue>interval</returnvalue> |
| </para> |
| <para> |
| Computes the <firstterm>continuous percentile</firstterm>, a value |
| corresponding to the specified <parameter>fraction</parameter> |
| within the ordered set of aggregated argument values. This will |
| interpolate between adjacent input items if needed. |
| </para></entry> |
| <entry>No</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>percentile_cont</function> ( <parameter>fractions</parameter> <type>double precision[]</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>double precision</type> ) |
| <returnvalue>double precision[]</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>percentile_cont</function> ( <parameter>fractions</parameter> <type>double precision[]</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>interval</type> ) |
| <returnvalue>interval[]</returnvalue> |
| </para> |
| <para> |
| Computes multiple continuous percentiles. The result is an array of |
| the same dimensions as the <parameter>fractions</parameter> |
| parameter, with each non-null element replaced by the (possibly |
| interpolated) value corresponding to that percentile. |
| </para></entry> |
| <entry>No</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>percentile</primary> |
| <secondary>discrete</secondary> |
| </indexterm> |
| <function>percentile_disc</function> ( <parameter>fraction</parameter> <type>double precision</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>anyelement</type> ) |
| <returnvalue>anyelement</returnvalue> |
| </para> |
| <para> |
| Computes the <firstterm>discrete percentile</firstterm>, the first |
| value within the ordered set of aggregated argument values whose |
| position in the ordering equals or exceeds the |
| specified <parameter>fraction</parameter>. The aggregated |
| argument must be of a sortable type. |
| </para></entry> |
| <entry>No</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>percentile_disc</function> ( <parameter>fractions</parameter> <type>double precision[]</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>anyelement</type> ) |
| <returnvalue>anyarray</returnvalue> |
| </para> |
| <para> |
| Computes multiple discrete percentiles. The result is an array of the |
| same dimensions as the <parameter>fractions</parameter> parameter, |
| with each non-null element replaced by the input value corresponding |
| to that percentile. |
| The aggregated argument must be of a sortable type. |
| </para></entry> |
| <entry>No</entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <indexterm> |
| <primary>hypothetical-set aggregate</primary> |
| <secondary>built-in</secondary> |
| </indexterm> |
| |
| <para> |
| Each of the <quote>hypothetical-set</quote> aggregates listed in |
| <xref linkend="functions-hypothetical-table"/> is associated with a |
| window function of the same name defined in |
| <xref linkend="functions-window"/>. In each case, the aggregate's result |
| is the value that the associated window function would have |
| returned for the <quote>hypothetical</quote> row constructed from |
| <replaceable>args</replaceable>, if such a row had been added to the sorted |
| group of rows represented by the <replaceable>sorted_args</replaceable>. |
| For each of these functions, the list of direct arguments |
| given in <replaceable>args</replaceable> must match the number and types of |
| the aggregated arguments given in <replaceable>sorted_args</replaceable>. |
| Unlike most built-in aggregates, these aggregates are not strict, that is |
| they do not drop input rows containing nulls. Null values sort according |
| to the rule specified in the <literal>ORDER BY</literal> clause. |
| </para> |
| |
| <table id="functions-hypothetical-table"> |
| <title>Hypothetical-Set Aggregate Functions</title> |
| <tgroup cols="2"> |
| <colspec colname="col1" colwidth="10*"/> |
| <colspec colname="col2" colwidth="1*"/> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| <entry>Partial Mode</entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>rank</primary> |
| <secondary>hypothetical</secondary> |
| </indexterm> |
| <function>rank</function> ( <replaceable>args</replaceable> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <replaceable>sorted_args</replaceable> ) |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para> |
| Computes the rank of the hypothetical row, with gaps; that is, the row |
| number of the first row in its peer group. |
| </para></entry> |
| <entry>No</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>dense_rank</primary> |
| <secondary>hypothetical</secondary> |
| </indexterm> |
| <function>dense_rank</function> ( <replaceable>args</replaceable> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <replaceable>sorted_args</replaceable> ) |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para> |
| Computes the rank of the hypothetical row, without gaps; this function |
| effectively counts peer groups. |
| </para></entry> |
| <entry>No</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>percent_rank</primary> |
| <secondary>hypothetical</secondary> |
| </indexterm> |
| <function>percent_rank</function> ( <replaceable>args</replaceable> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <replaceable>sorted_args</replaceable> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Computes the relative rank of the hypothetical row, that is |
| (<function>rank</function> - 1) / (total rows - 1). |
| The value thus ranges from 0 to 1 inclusive. |
| </para></entry> |
| <entry>No</entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>cume_dist</primary> |
| <secondary>hypothetical</secondary> |
| </indexterm> |
| <function>cume_dist</function> ( <replaceable>args</replaceable> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <replaceable>sorted_args</replaceable> ) |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Computes the cumulative distribution, that is (number of rows |
| preceding or peers with hypothetical row) / (total rows). The value |
| thus ranges from 1/<parameter>N</parameter> to 1. |
| </para></entry> |
| <entry>No</entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <table id="functions-grouping-table"> |
| <title>Grouping Operations</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>GROUPING</primary> |
| </indexterm> |
| <function>GROUPING</function> ( <replaceable>group_by_expression(s)</replaceable> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns a bit mask indicating which <literal>GROUP BY</literal> |
| 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. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| The grouping operations shown in |
| <xref linkend="functions-grouping-table"/> are used in conjunction with |
| grouping sets (see <xref linkend="queries-grouping-sets"/>) to distinguish |
| result rows. The arguments to the <literal>GROUPING</literal> function |
| are not actually evaluated, but they must exactly match expressions given |
| in the <literal>GROUP BY</literal> clause of the associated query level. |
| For example: |
| <screen> |
| <prompt>=></prompt> <userinput>SELECT * FROM items_sold;</userinput> |
| make | model | sales |
| -------+-------+------- |
| Foo | GT | 10 |
| Foo | Tour | 20 |
| Bar | City | 15 |
| Bar | Sport | 5 |
| (4 rows) |
| |
| <prompt>=></prompt> <userinput>SELECT make, model, GROUPING(make,model), sum(sales) FROM items_sold GROUP BY ROLLUP(make,model);</userinput> |
| make | model | grouping | sum |
| -------+-------+----------+----- |
| Foo | GT | 0 | 10 |
| Foo | Tour | 0 | 20 |
| Bar | City | 0 | 15 |
| Bar | Sport | 0 | 5 |
| Foo | | 1 | 30 |
| Bar | | 1 | 20 |
| | | 3 | 50 |
| (7 rows) |
| </screen> |
| Here, the <literal>grouping</literal> value <literal>0</literal> in the |
| first four rows shows that those have been grouped normally, over both the |
| grouping columns. The value <literal>1</literal> indicates |
| that <literal>model</literal> was not grouped by in the next-to-last two |
| rows, and the value <literal>3</literal> indicates that |
| neither <literal>make</literal> nor <literal>model</literal> was grouped |
| by in the last row (which therefore is an aggregate over all the input |
| rows). |
| </para> |
| |
| </sect1> |
| |
| <sect1 id="functions-window"> |
| <title>Window Functions</title> |
| |
| <indexterm zone="functions-window"> |
| <primary>window function</primary> |
| <secondary>built-in</secondary> |
| </indexterm> |
| |
| <para> |
| <firstterm>Window functions</firstterm> provide the ability to perform |
| calculations across sets of rows that are related to the current query |
| row. See <xref linkend="tutorial-window"/> for an introduction to this |
| feature, and <xref linkend="syntax-window-functions"/> for syntax |
| details. |
| </para> |
| |
| <para> |
| The built-in window functions are listed in |
| <xref linkend="functions-window-table"/>. Note that these functions |
| <emphasis>must</emphasis> be invoked using window function syntax, i.e., an |
| <literal>OVER</literal> clause is required. |
| </para> |
| |
| <para> |
| In addition to these functions, any built-in or user-defined |
| ordinary aggregate (i.e., not ordered-set or hypothetical-set aggregates) |
| can be used as a window function; see |
| <xref linkend="functions-aggregate"/> for a list of the built-in aggregates. |
| Aggregate functions act as window functions only when an <literal>OVER</literal> |
| clause follows the call; otherwise they act as plain aggregates |
| and return a single row for the entire set. |
| </para> |
| |
| <table id="functions-window-table"> |
| <title>General-Purpose Window Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>row_number</primary> |
| </indexterm> |
| <function>row_number</function> () |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para> |
| Returns the number of the current row within its partition, counting |
| from 1. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>rank</primary> |
| </indexterm> |
| <function>rank</function> () |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para> |
| Returns the rank of the current row, with gaps; that is, |
| the <function>row_number</function> of the first row in its peer |
| group. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>dense_rank</primary> |
| </indexterm> |
| <function>dense_rank</function> () |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para> |
| Returns the rank of the current row, without gaps; this function |
| effectively counts peer groups. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>percent_rank</primary> |
| </indexterm> |
| <function>percent_rank</function> () |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Returns the relative rank of the current row, that is |
| (<function>rank</function> - 1) / (total partition rows - 1). |
| The value thus ranges from 0 to 1 inclusive. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>cume_dist</primary> |
| </indexterm> |
| <function>cume_dist</function> () |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Returns the cumulative distribution, that is (number of partition rows |
| preceding or peers with current row) / (total partition rows). |
| The value thus ranges from 1/<parameter>N</parameter> to 1. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>ntile</primary> |
| </indexterm> |
| <function>ntile</function> ( <parameter>num_buckets</parameter> <type>integer</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns an integer ranging from 1 to the argument value, dividing the |
| partition as equally as possible. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>lag</primary> |
| </indexterm> |
| <function>lag</function> ( <parameter>value</parameter> <type>anycompatible</type> |
| <optional>, <parameter>offset</parameter> <type>integer</type> |
| <optional>, <parameter>default</parameter> <type>anycompatible</type> </optional></optional> ) |
| <returnvalue>anycompatible</returnvalue> |
| </para> |
| <para> |
| Returns <parameter>value</parameter> evaluated at |
| the row that is <parameter>offset</parameter> |
| rows before the current row within the partition; if there is no such |
| row, instead returns <parameter>default</parameter> |
| (which must be of a type compatible with |
| <parameter>value</parameter>). |
| Both <parameter>offset</parameter> and |
| <parameter>default</parameter> are evaluated |
| with respect to the current row. If omitted, |
| <parameter>offset</parameter> defaults to 1 and |
| <parameter>default</parameter> to <literal>NULL</literal>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>lead</primary> |
| </indexterm> |
| <function>lead</function> ( <parameter>value</parameter> <type>anycompatible</type> |
| <optional>, <parameter>offset</parameter> <type>integer</type> |
| <optional>, <parameter>default</parameter> <type>anycompatible</type> </optional></optional> ) |
| <returnvalue>anycompatible</returnvalue> |
| </para> |
| <para> |
| Returns <parameter>value</parameter> evaluated at |
| the row that is <parameter>offset</parameter> |
| rows after the current row within the partition; if there is no such |
| row, instead returns <parameter>default</parameter> |
| (which must be of a type compatible with |
| <parameter>value</parameter>). |
| Both <parameter>offset</parameter> and |
| <parameter>default</parameter> are evaluated |
| with respect to the current row. If omitted, |
| <parameter>offset</parameter> defaults to 1 and |
| <parameter>default</parameter> to <literal>NULL</literal>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>first_value</primary> |
| </indexterm> |
| <function>first_value</function> ( <parameter>value</parameter> <type>anyelement</type> ) |
| <returnvalue>anyelement</returnvalue> |
| </para> |
| <para> |
| Returns <parameter>value</parameter> evaluated |
| at the row that is the first row of the window frame. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>last_value</primary> |
| </indexterm> |
| <function>last_value</function> ( <parameter>value</parameter> <type>anyelement</type> ) |
| <returnvalue>anyelement</returnvalue> |
| </para> |
| <para> |
| Returns <parameter>value</parameter> evaluated |
| at the row that is the last row of the window frame. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>nth_value</primary> |
| </indexterm> |
| <function>nth_value</function> ( <parameter>value</parameter> <type>anyelement</type>, <parameter>n</parameter> <type>integer</type> ) |
| <returnvalue>anyelement</returnvalue> |
| </para> |
| <para> |
| Returns <parameter>value</parameter> evaluated |
| at the row that is the <parameter>n</parameter>'th |
| row of the window frame (counting from 1); |
| returns <literal>NULL</literal> if there is no such row. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| All of the functions listed in |
| <xref linkend="functions-window-table"/> depend on the sort ordering |
| specified by the <literal>ORDER BY</literal> clause of the associated window |
| definition. Rows that are not distinct when considering only the |
| <literal>ORDER BY</literal> columns are said to be <firstterm>peers</firstterm>. |
| The four ranking functions (including <function>cume_dist</function>) are |
| defined so that they give the same answer for all rows of a peer group. |
| </para> |
| |
| <para> |
| Note that <function>first_value</function>, <function>last_value</function>, and |
| <function>nth_value</function> consider only the rows within the <quote>window |
| frame</quote>, which by default contains the rows from the start of the |
| partition through the last peer of the current row. This is |
| likely to give unhelpful results for <function>last_value</function> and |
| sometimes also <function>nth_value</function>. You can redefine the frame by |
| adding a suitable frame specification (<literal>RANGE</literal>, |
| <literal>ROWS</literal> or <literal>GROUPS</literal>) to |
| the <literal>OVER</literal> clause. |
| See <xref linkend="syntax-window-functions"/> for more information |
| about frame specifications. |
| </para> |
| |
| <para> |
| When an aggregate function is used as a window function, it aggregates |
| over the rows within the current row's window frame. |
| An aggregate used with <literal>ORDER BY</literal> and the default window frame |
| definition produces a <quote>running sum</quote> type of behavior, which may or |
| may not be what's wanted. To obtain |
| aggregation over the whole partition, omit <literal>ORDER BY</literal> or use |
| <literal>ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING</literal>. |
| Other frame specifications can be used to obtain other effects. |
| </para> |
| |
| <note> |
| <para> |
| The SQL standard defines a <literal>RESPECT NULLS</literal> or |
| <literal>IGNORE NULLS</literal> option for <function>lead</function>, <function>lag</function>, |
| <function>first_value</function>, <function>last_value</function>, and |
| <function>nth_value</function>. This is not implemented in |
| <productname>PostgreSQL</productname>: the behavior is always the |
| same as the standard's default, namely <literal>RESPECT NULLS</literal>. |
| Likewise, the standard's <literal>FROM FIRST</literal> or <literal>FROM LAST</literal> |
| option for <function>nth_value</function> is not implemented: only the |
| default <literal>FROM FIRST</literal> behavior is supported. (You can achieve |
| the result of <literal>FROM LAST</literal> by reversing the <literal>ORDER BY</literal> |
| ordering.) |
| </para> |
| </note> |
| |
| </sect1> |
| |
| <sect1 id="functions-subquery"> |
| <title>Subquery Expressions</title> |
| |
| <indexterm> |
| <primary>EXISTS</primary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>IN</primary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>NOT IN</primary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>ANY</primary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>ALL</primary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>SOME</primary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>subquery</primary> |
| </indexterm> |
| |
| <para> |
| This section describes the <acronym>SQL</acronym>-compliant subquery |
| expressions available in <productname>PostgreSQL</productname>. |
| All of the expression forms documented in this section return |
| Boolean (true/false) results. |
| </para> |
| |
| <sect2 id="functions-subquery-exists"> |
| <title><literal>EXISTS</literal></title> |
| |
| <synopsis> |
| EXISTS (<replaceable>subquery</replaceable>) |
| </synopsis> |
| |
| <para> |
| The argument of <token>EXISTS</token> is an arbitrary <command>SELECT</command> statement, |
| or <firstterm>subquery</firstterm>. The |
| subquery is evaluated to determine whether it returns any rows. |
| If it returns at least one row, the result of <token>EXISTS</token> is |
| <quote>true</quote>; if the subquery returns no rows, the result of <token>EXISTS</token> |
| is <quote>false</quote>. |
| </para> |
| |
| <para> |
| The subquery can refer to variables from the surrounding query, |
| which will act as constants during any one evaluation of the subquery. |
| </para> |
| |
| <para> |
| The subquery will generally only be executed long enough to determine |
| whether at least one row is returned, not all the way to completion. |
| It is unwise to write a subquery that has side effects (such as |
| calling sequence functions); whether the side effects occur |
| might be unpredictable. |
| </para> |
| |
| <para> |
| Since the result depends only on whether any rows are returned, |
| and not on the contents of those rows, the output list of the |
| subquery is normally unimportant. A common coding convention is |
| to write all <literal>EXISTS</literal> tests in the form |
| <literal>EXISTS(SELECT 1 WHERE ...)</literal>. There are exceptions to |
| this rule however, such as subqueries that use <token>INTERSECT</token>. |
| </para> |
| |
| <para> |
| This simple example is like an inner join on <literal>col2</literal>, but |
| it produces at most one output row for each <literal>tab1</literal> row, |
| even if there are several matching <literal>tab2</literal> rows: |
| <screen> |
| SELECT col1 |
| FROM tab1 |
| WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2); |
| </screen> |
| </para> |
| </sect2> |
| |
| <sect2 id="functions-subquery-in"> |
| <title><literal>IN</literal></title> |
| |
| <synopsis> |
| <replaceable>expression</replaceable> IN (<replaceable>subquery</replaceable>) |
| </synopsis> |
| |
| <para> |
| The right-hand side 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 <token>IN</token> is <quote>true</quote> if any equal subquery row is found. |
| The result is <quote>false</quote> if no equal row is found (including the |
| case where the subquery returns no rows). |
| </para> |
| |
| <para> |
| 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 <token>IN</token> construct will be null, not false. |
| This is in accordance with SQL's normal rules for Boolean combinations |
| of null values. |
| </para> |
| |
| <para> |
| As with <token>EXISTS</token>, it's unwise to assume that the subquery will |
| be evaluated completely. |
| </para> |
| |
| <synopsis> |
| <replaceable>row_constructor</replaceable> IN (<replaceable>subquery</replaceable>) |
| </synopsis> |
| |
| <para> |
| The left-hand side of this form of <token>IN</token> is a row constructor, |
| as described in <xref linkend="sql-syntax-row-constructors"/>. |
| The right-hand side is a parenthesized |
| subquery, which must return exactly as many columns as there are |
| expressions in the left-hand row. The left-hand expressions are |
| evaluated and compared row-wise to each row of the subquery result. |
| The result of <token>IN</token> is <quote>true</quote> if any equal subquery row is found. |
| The result is <quote>false</quote> if no equal row is found (including the |
| case where the subquery returns no rows). |
| </para> |
| |
| <para> |
| As usual, null values in the rows are combined per |
| the normal rules of SQL Boolean expressions. Two rows are considered |
| 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 all the per-row results are either unequal or null, with at least one |
| null, then the result of <token>IN</token> is null. |
| </para> |
| </sect2> |
| |
| <sect2 id="functions-subquery-notin"> |
| <title><literal>NOT IN</literal></title> |
| |
| <synopsis> |
| <replaceable>expression</replaceable> NOT IN (<replaceable>subquery</replaceable>) |
| </synopsis> |
| |
| <para> |
| The right-hand side 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 <token>NOT IN</token> is <quote>true</quote> if only unequal subquery rows |
| are found (including the case where the subquery returns no rows). |
| The result is <quote>false</quote> if any equal row is found. |
| </para> |
| |
| <para> |
| 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 <token>NOT IN</token> construct will be null, not true. |
| This is in accordance with SQL's normal rules for Boolean combinations |
| of null values. |
| </para> |
| |
| <para> |
| As with <token>EXISTS</token>, it's unwise to assume that the subquery will |
| be evaluated completely. |
| </para> |
| |
| <synopsis> |
| <replaceable>row_constructor</replaceable> NOT IN (<replaceable>subquery</replaceable>) |
| </synopsis> |
| |
| <para> |
| The left-hand side of this form of <token>NOT IN</token> is a row constructor, |
| as described in <xref linkend="sql-syntax-row-constructors"/>. |
| The right-hand side is a parenthesized |
| subquery, which must return exactly as many columns as there are |
| expressions in the left-hand row. The left-hand expressions are |
| evaluated and compared row-wise to each row of the subquery result. |
| The result of <token>NOT IN</token> is <quote>true</quote> if only unequal subquery rows |
| are found (including the case where the subquery returns no rows). |
| The result is <quote>false</quote> if any equal row is found. |
| </para> |
| |
| <para> |
| As usual, null values in the rows are combined per |
| the normal rules of SQL Boolean expressions. Two rows are considered |
| 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 all the per-row results are either unequal or null, with at least one |
| null, then the result of <token>NOT IN</token> is null. |
| </para> |
| </sect2> |
| |
| <sect2 id="functions-subquery-any-some"> |
| <title><literal>ANY</literal>/<literal>SOME</literal></title> |
| |
| <synopsis> |
| <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>) |
| <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>) |
| </synopsis> |
| |
| <para> |
| The right-hand side 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 <replaceable>operator</replaceable>, which must yield a Boolean |
| result. |
| The result of <token>ANY</token> is <quote>true</quote> if any true result is obtained. |
| The result is <quote>false</quote> if no true result is found (including the |
| case where the subquery returns no rows). |
| </para> |
| |
| <para> |
| <token>SOME</token> is a synonym for <token>ANY</token>. |
| <token>IN</token> is equivalent to <literal>= ANY</literal>. |
| </para> |
| |
| <para> |
| 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 <token>ANY</token> construct |
| will be null, not false. |
| This is in accordance with SQL's normal rules for Boolean combinations |
| of null values. |
| </para> |
| |
| <para> |
| As with <token>EXISTS</token>, it's unwise to assume that the subquery will |
| be evaluated completely. |
| </para> |
| |
| <synopsis> |
| <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>) |
| <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>) |
| </synopsis> |
| |
| <para> |
| The left-hand side of this form of <token>ANY</token> is a row constructor, |
| as described in <xref linkend="sql-syntax-row-constructors"/>. |
| The right-hand side is a parenthesized |
| subquery, which must return exactly as many columns as there are |
| expressions in the left-hand row. The left-hand expressions are |
| evaluated and compared row-wise to each row of the subquery result, |
| using the given <replaceable>operator</replaceable>. |
| The result of <token>ANY</token> is <quote>true</quote> if the comparison |
| returns true for any subquery row. |
| The result is <quote>false</quote> if the comparison returns false for every |
| subquery row (including the case where the subquery returns no |
| rows). |
| The result is NULL if no comparison with a subquery row returns true, |
| and at least one comparison returns NULL. |
| </para> |
| |
| <para> |
| See <xref linkend="row-wise-comparison"/> for details about the meaning |
| of a row constructor comparison. |
| </para> |
| </sect2> |
| |
| <sect2 id="functions-subquery-all"> |
| <title><literal>ALL</literal></title> |
| |
| <synopsis> |
| <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>) |
| </synopsis> |
| |
| <para> |
| The right-hand side 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 <replaceable>operator</replaceable>, which must yield a Boolean |
| result. |
| The result of <token>ALL</token> is <quote>true</quote> if all rows yield true |
| (including the case where the subquery returns no rows). |
| The result is <quote>false</quote> if any false result is found. |
| The result is NULL if no comparison with a subquery row returns false, |
| and at least one comparison returns NULL. |
| </para> |
| |
| <para> |
| <token>NOT IN</token> is equivalent to <literal><> ALL</literal>. |
| </para> |
| |
| <para> |
| As with <token>EXISTS</token>, it's unwise to assume that the subquery will |
| be evaluated completely. |
| </para> |
| |
| <synopsis> |
| <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>) |
| </synopsis> |
| |
| <para> |
| The left-hand side of this form of <token>ALL</token> is a row constructor, |
| as described in <xref linkend="sql-syntax-row-constructors"/>. |
| The right-hand side is a parenthesized |
| subquery, which must return exactly as many columns as there are |
| expressions in the left-hand row. The left-hand expressions are |
| evaluated and compared row-wise to each row of the subquery result, |
| using the given <replaceable>operator</replaceable>. |
| The result of <token>ALL</token> is <quote>true</quote> if the comparison |
| returns true for all subquery rows (including the |
| case where the subquery returns no rows). |
| The result is <quote>false</quote> if the comparison returns false for any |
| subquery row. |
| The result is NULL if no comparison with a subquery row returns false, |
| and at least one comparison returns NULL. |
| </para> |
| |
| <para> |
| See <xref linkend="row-wise-comparison"/> for details about the meaning |
| of a row constructor comparison. |
| </para> |
| </sect2> |
| |
| <sect2> |
| <title>Single-Row Comparison</title> |
| |
| <indexterm zone="functions-subquery"> |
| <primary>comparison</primary> |
| <secondary>subquery result row</secondary> |
| </indexterm> |
| |
| <synopsis> |
| <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> (<replaceable>subquery</replaceable>) |
| </synopsis> |
| |
| <para> |
| The left-hand side is a row constructor, |
| as described in <xref linkend="sql-syntax-row-constructors"/>. |
| The right-hand side is a parenthesized subquery, which must return exactly |
| as many columns as there are expressions in the left-hand row. Furthermore, |
| the subquery cannot 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. |
| </para> |
| |
| <para> |
| See <xref linkend="row-wise-comparison"/> for details about the meaning |
| of a row constructor comparison. |
| </para> |
| </sect2> |
| </sect1> |
| |
| |
| <sect1 id="functions-comparisons"> |
| <title>Row and Array Comparisons</title> |
| |
| <indexterm> |
| <primary>IN</primary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>NOT IN</primary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>ANY</primary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>ALL</primary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>SOME</primary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>composite type</primary> |
| <secondary>comparison</secondary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>row-wise comparison</primary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>comparison</primary> |
| <secondary>composite type</secondary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>comparison</primary> |
| <secondary>row constructor</secondary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>IS DISTINCT FROM</primary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>IS NOT DISTINCT FROM</primary> |
| </indexterm> |
| |
| <para> |
| This section describes several specialized constructs for making |
| multiple comparisons between groups of values. These forms are |
| syntactically related to the subquery forms of the previous section, |
| but do not involve subqueries. |
| The forms involving array subexpressions are |
| <productname>PostgreSQL</productname> extensions; the rest are |
| <acronym>SQL</acronym>-compliant. |
| All of the expression forms documented in this section return |
| Boolean (true/false) results. |
| </para> |
| |
| <sect2 id="functions-comparisons-in-scalar"> |
| <title><literal>IN</literal></title> |
| |
| <synopsis> |
| <replaceable>expression</replaceable> IN (<replaceable>value</replaceable> <optional>, ...</optional>) |
| </synopsis> |
| |
| <para> |
| The right-hand side is a parenthesized list |
| of scalar expressions. The result is <quote>true</quote> if the left-hand expression's |
| result is equal to any of the right-hand expressions. This is a shorthand |
| notation for |
| |
| <synopsis> |
| <replaceable>expression</replaceable> = <replaceable>value1</replaceable> |
| OR |
| <replaceable>expression</replaceable> = <replaceable>value2</replaceable> |
| OR |
| ... |
| </synopsis> |
| </para> |
| |
| <para> |
| 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 <token>IN</token> construct will be null, not false. |
| This is in accordance with SQL's normal rules for Boolean combinations |
| of null values. |
| </para> |
| </sect2> |
| |
| <sect2> |
| <title><literal>NOT IN</literal></title> |
| |
| <synopsis> |
| <replaceable>expression</replaceable> NOT IN (<replaceable>value</replaceable> <optional>, ...</optional>) |
| </synopsis> |
| |
| <para> |
| The right-hand side is a parenthesized list |
| of scalar expressions. The result is <quote>true</quote> if the left-hand expression's |
| result is unequal to all of the right-hand expressions. This is a shorthand |
| notation for |
| |
| <synopsis> |
| <replaceable>expression</replaceable> <> <replaceable>value1</replaceable> |
| AND |
| <replaceable>expression</replaceable> <> <replaceable>value2</replaceable> |
| AND |
| ... |
| </synopsis> |
| </para> |
| |
| <para> |
| 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 <token>NOT IN</token> 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. |
| </para> |
| |
| <tip> |
| <para> |
| <literal>x NOT IN y</literal> is equivalent to <literal>NOT (x IN y)</literal> in all |
| cases. However, null values are much more likely to trip up the novice when |
| working with <token>NOT IN</token> than when working with <token>IN</token>. |
| It is best to express your condition positively if possible. |
| </para> |
| </tip> |
| </sect2> |
| |
| <sect2> |
| <title><literal>ANY</literal>/<literal>SOME</literal> (array)</title> |
| |
| <synopsis> |
| <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>array expression</replaceable>) |
| <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>array expression</replaceable>) |
| </synopsis> |
| |
| <para> |
| The right-hand side is a parenthesized expression, which must yield an |
| array value. |
| The left-hand expression |
| is evaluated and compared to each element of the array using the |
| given <replaceable>operator</replaceable>, which must yield a Boolean |
| result. |
| The result of <token>ANY</token> is <quote>true</quote> if any true result is obtained. |
| The result is <quote>false</quote> if no true result is found (including the |
| case where the array has zero elements). |
| </para> |
| |
| <para> |
| If the array expression yields a null array, the result of |
| <token>ANY</token> will be null. If the left-hand expression yields null, |
| the result of <token>ANY</token> is ordinarily null (though a non-strict |
| comparison operator could possibly yield a different result). |
| Also, if the right-hand array contains any null elements and no true |
| comparison result is obtained, the result of <token>ANY</token> |
| will be null, not false (again, assuming a strict comparison operator). |
| This is in accordance with SQL's normal rules for Boolean combinations |
| of null values. |
| </para> |
| |
| <para> |
| <token>SOME</token> is a synonym for <token>ANY</token>. |
| </para> |
| </sect2> |
| |
| <sect2> |
| <title><literal>ALL</literal> (array)</title> |
| |
| <synopsis> |
| <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>array expression</replaceable>) |
| </synopsis> |
| |
| <para> |
| The right-hand side is a parenthesized expression, which must yield an |
| array value. |
| The left-hand expression |
| is evaluated and compared to each element of the array using the |
| given <replaceable>operator</replaceable>, which must yield a Boolean |
| result. |
| The result of <token>ALL</token> is <quote>true</quote> if all comparisons yield true |
| (including the case where the array has zero elements). |
| The result is <quote>false</quote> if any false result is found. |
| </para> |
| |
| <para> |
| If the array expression yields a null array, the result of |
| <token>ALL</token> will be null. If the left-hand expression yields null, |
| the result of <token>ALL</token> is ordinarily null (though a non-strict |
| comparison operator could possibly yield a different result). |
| Also, if the right-hand array contains any null elements and no false |
| comparison result is obtained, the result of <token>ALL</token> |
| will be null, not true (again, assuming a strict comparison operator). |
| This is in accordance with SQL's normal rules for Boolean combinations |
| of null values. |
| </para> |
| </sect2> |
| |
| <sect2 id="row-wise-comparison"> |
| <title>Row Constructor Comparison</title> |
| |
| <synopsis> |
| <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> <replaceable>row_constructor</replaceable> |
| </synopsis> |
| |
| <para> |
| Each side is a row constructor, |
| as described in <xref linkend="sql-syntax-row-constructors"/>. |
| The two row values must have the same number of fields. |
| Each side is evaluated and they are compared row-wise. Row constructor |
| comparisons are allowed when the <replaceable>operator</replaceable> is |
| <literal>=</literal>, |
| <literal><></literal>, |
| <literal><</literal>, |
| <literal><=</literal>, |
| <literal>></literal> or |
| <literal>>=</literal>. |
| Every row element must be of a type which has a default B-tree operator |
| class or the attempted comparison may generate an error. |
| </para> |
| |
| <note> |
| <para> |
| Errors related to the number or types of elements might not occur if |
| the comparison is resolved using earlier columns. |
| </para> |
| </note> |
| |
| <para> |
| The <literal>=</literal> and <literal><></literal> cases work slightly differently |
| from the others. Two rows are considered |
| 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 the row comparison is unknown (null). |
| </para> |
| |
| <para> |
| For the <literal><</literal>, <literal><=</literal>, <literal>></literal> and |
| <literal>>=</literal> cases, the row elements are compared left-to-right, |
| stopping as soon as an unequal or null pair of elements is found. |
| If either of this pair of elements is null, the result of the |
| row comparison is unknown (null); otherwise comparison of this pair |
| of elements determines the result. For example, |
| <literal>ROW(1,2,NULL) < ROW(1,3,0)</literal> |
| yields true, not null, because the third pair of elements are not |
| considered. |
| </para> |
| |
| <note> |
| <para> |
| Prior to <productname>PostgreSQL</productname> 8.2, the |
| <literal><</literal>, <literal><=</literal>, <literal>></literal> and <literal>>=</literal> |
| cases were not handled per SQL specification. A comparison like |
| <literal>ROW(a,b) < ROW(c,d)</literal> |
| was implemented as |
| <literal>a < c AND b < d</literal> |
| whereas the correct behavior is equivalent to |
| <literal>a < c OR (a = c AND b < d)</literal>. |
| </para> |
| </note> |
| |
| <synopsis> |
| <replaceable>row_constructor</replaceable> IS DISTINCT FROM <replaceable>row_constructor</replaceable> |
| </synopsis> |
| |
| <para> |
| This construct is similar to a <literal><></literal> row comparison, |
| but it does not yield null for null inputs. Instead, any null value is |
| considered unequal to (distinct from) any non-null value, and any two |
| nulls are considered equal (not distinct). Thus the result will |
| either be true or false, never null. |
| </para> |
| |
| <synopsis> |
| <replaceable>row_constructor</replaceable> IS NOT DISTINCT FROM <replaceable>row_constructor</replaceable> |
| </synopsis> |
| |
| <para> |
| This construct is similar to a <literal>=</literal> row comparison, |
| but it does not yield null for null inputs. Instead, any null value is |
| considered unequal to (distinct from) any non-null value, and any two |
| nulls are considered equal (not distinct). Thus the result will always |
| be either true or false, never null. |
| </para> |
| |
| </sect2> |
| |
| <sect2 id="composite-type-comparison"> |
| <title>Composite Type Comparison</title> |
| |
| <synopsis> |
| <replaceable>record</replaceable> <replaceable>operator</replaceable> <replaceable>record</replaceable> |
| </synopsis> |
| |
| <para> |
| The SQL specification requires row-wise comparison to return NULL if the |
| result depends on comparing two NULL values or a NULL and a non-NULL. |
| <productname>PostgreSQL</productname> does this only when comparing the |
| results of two row constructors (as in |
| <xref linkend="row-wise-comparison"/>) or comparing a row constructor |
| to the output of a subquery (as in <xref linkend="functions-subquery"/>). |
| In other contexts where two composite-type values are compared, two |
| NULL field values are considered equal, and a NULL is considered larger |
| than a non-NULL. This is necessary in order to have consistent sorting |
| and indexing behavior for composite types. |
| </para> |
| |
| <para> |
| Each side is evaluated and they are compared row-wise. Composite type |
| comparisons are allowed when the <replaceable>operator</replaceable> is |
| <literal>=</literal>, |
| <literal><></literal>, |
| <literal><</literal>, |
| <literal><=</literal>, |
| <literal>></literal> or |
| <literal>>=</literal>, |
| or has semantics similar to one of these. (To be specific, an operator |
| can be a row comparison operator if it is a member of a B-tree operator |
| class, or is the negator of the <literal>=</literal> member of a B-tree operator |
| class.) The default behavior of the above operators is the same as for |
| <literal>IS [ NOT ] DISTINCT FROM</literal> for row constructors (see |
| <xref linkend="row-wise-comparison"/>). |
| </para> |
| |
| <para> |
| To support matching of rows which include elements without a default |
| B-tree operator class, the following operators are defined for composite |
| type comparison: |
| <literal>*=</literal>, |
| <literal>*<></literal>, |
| <literal>*<</literal>, |
| <literal>*<=</literal>, |
| <literal>*></literal>, and |
| <literal>*>=</literal>. |
| These operators compare the internal binary representation of the two |
| rows. Two rows might have a different binary representation even |
| though comparisons of the two rows with the equality operator is true. |
| The ordering of rows under these comparison operators is deterministic |
| but not otherwise meaningful. These operators are used internally |
| for materialized views and might be useful for other specialized |
| purposes such as replication and B-Tree deduplication (see <xref |
| linkend="btree-deduplication"/>). They are not intended to be |
| generally useful for writing queries, though. |
| </para> |
| </sect2> |
| </sect1> |
| |
| <sect1 id="functions-srf"> |
| <title>Set Returning Functions</title> |
| |
| <indexterm zone="functions-srf"> |
| <primary>set returning functions</primary> |
| <secondary>functions</secondary> |
| </indexterm> |
| |
| <para> |
| This section describes functions that possibly return more than one row. |
| The most widely used functions in this class are series generating |
| functions, as detailed in <xref linkend="functions-srf-series"/> and |
| <xref linkend="functions-srf-subscripts"/>. Other, more specialized |
| set-returning functions are described elsewhere in this manual. |
| See <xref linkend="queries-tablefunctions"/> for ways to combine multiple |
| set-returning functions. |
| </para> |
| |
| <table id="functions-srf-series"> |
| <title>Series Generating Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>generate_series</primary> |
| </indexterm> |
| <function>generate_series</function> ( <parameter>start</parameter> <type>integer</type>, <parameter>stop</parameter> <type>integer</type> <optional>, <parameter>step</parameter> <type>integer</type> </optional> ) |
| <returnvalue>setof integer</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>generate_series</function> ( <parameter>start</parameter> <type>bigint</type>, <parameter>stop</parameter> <type>bigint</type> <optional>, <parameter>step</parameter> <type>bigint</type> </optional> ) |
| <returnvalue>setof bigint</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>generate_series</function> ( <parameter>start</parameter> <type>numeric</type>, <parameter>stop</parameter> <type>numeric</type> <optional>, <parameter>step</parameter> <type>numeric</type> </optional> ) |
| <returnvalue>setof numeric</returnvalue> |
| </para> |
| <para> |
| Generates a series of values from <parameter>start</parameter> |
| to <parameter>stop</parameter>, with a step size |
| of <parameter>step</parameter>. <parameter>step</parameter> |
| defaults to 1. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>generate_series</function> ( <parameter>start</parameter> <type>timestamp</type>, <parameter>stop</parameter> <type>timestamp</type>, <parameter>step</parameter> <type>interval</type> ) |
| <returnvalue>setof timestamp</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>generate_series</function> ( <parameter>start</parameter> <type>timestamp with time zone</type>, <parameter>stop</parameter> <type>timestamp with time zone</type>, <parameter>step</parameter> <type>interval</type> ) |
| <returnvalue>setof timestamp with time zone</returnvalue> |
| </para> |
| <para> |
| Generates a series of values from <parameter>start</parameter> |
| to <parameter>stop</parameter>, with a step size |
| of <parameter>step</parameter>. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| When <parameter>step</parameter> is positive, zero rows are returned if |
| <parameter>start</parameter> is greater than <parameter>stop</parameter>. |
| Conversely, when <parameter>step</parameter> is negative, zero rows are |
| returned if <parameter>start</parameter> is less than <parameter>stop</parameter>. |
| Zero rows are also returned if any input is <literal>NULL</literal>. |
| It is an error |
| for <parameter>step</parameter> to be zero. Some examples follow: |
| <programlisting> |
| SELECT * FROM generate_series(2,4); |
| generate_series |
| ----------------- |
| 2 |
| 3 |
| 4 |
| (3 rows) |
| |
| SELECT * FROM generate_series(5,1,-2); |
| generate_series |
| ----------------- |
| 5 |
| 3 |
| 1 |
| (3 rows) |
| |
| SELECT * FROM generate_series(4,3); |
| generate_series |
| ----------------- |
| (0 rows) |
| |
| SELECT generate_series(1.1, 4, 1.3); |
| generate_series |
| ----------------- |
| 1.1 |
| 2.4 |
| 3.7 |
| (3 rows) |
| |
| -- this example relies on the date-plus-integer operator: |
| SELECT current_date + s.a AS dates FROM generate_series(0,14,7) AS s(a); |
| dates |
| ------------ |
| 2004-02-05 |
| 2004-02-12 |
| 2004-02-19 |
| (3 rows) |
| |
| SELECT * FROM generate_series('2008-03-01 00:00'::timestamp, |
| '2008-03-04 12:00', '10 hours'); |
| generate_series |
| --------------------- |
| 2008-03-01 00:00:00 |
| 2008-03-01 10:00:00 |
| 2008-03-01 20:00:00 |
| 2008-03-02 06:00:00 |
| 2008-03-02 16:00:00 |
| 2008-03-03 02:00:00 |
| 2008-03-03 12:00:00 |
| 2008-03-03 22:00:00 |
| 2008-03-04 08:00:00 |
| (9 rows) |
| </programlisting> |
| </para> |
| |
| <table id="functions-srf-subscripts"> |
| <title>Subscript Generating Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>generate_subscripts</primary> |
| </indexterm> |
| <function>generate_subscripts</function> ( <parameter>array</parameter> <type>anyarray</type>, <parameter>dim</parameter> <type>integer</type> ) |
| <returnvalue>setof integer</returnvalue> |
| </para> |
| <para> |
| Generates a series comprising the valid subscripts of |
| the <parameter>dim</parameter>'th dimension of the given array. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>generate_subscripts</function> ( <parameter>array</parameter> <type>anyarray</type>, <parameter>dim</parameter> <type>integer</type>, <parameter>reverse</parameter> <type>boolean</type> ) |
| <returnvalue>setof integer</returnvalue> |
| </para> |
| <para> |
| Generates a series comprising the valid subscripts of |
| the <parameter>dim</parameter>'th dimension of the given array. |
| When <parameter>reverse</parameter> is true, returns the series in |
| reverse order. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| <function>generate_subscripts</function> is a convenience function that generates |
| the set of valid subscripts for the specified dimension of the given |
| array. |
| Zero rows are returned for arrays that do not have the requested dimension, |
| or if any input is <literal>NULL</literal>. |
| Some examples follow: |
| <programlisting> |
| -- basic usage: |
| SELECT generate_subscripts('{NULL,1,NULL,2}'::int[], 1) AS s; |
| s |
| --- |
| 1 |
| 2 |
| 3 |
| 4 |
| (4 rows) |
| |
| -- presenting an array, the subscript and the subscripted |
| -- value requires a subquery: |
| SELECT * FROM arrays; |
| a |
| -------------------- |
| {-1,-2} |
| {100,200,300} |
| (2 rows) |
| |
| SELECT a AS array, s AS subscript, a[s] AS value |
| FROM (SELECT generate_subscripts(a, 1) AS s, a FROM arrays) foo; |
| array | subscript | value |
| ---------------+-----------+------- |
| {-1,-2} | 1 | -1 |
| {-1,-2} | 2 | -2 |
| {100,200,300} | 1 | 100 |
| {100,200,300} | 2 | 200 |
| {100,200,300} | 3 | 300 |
| (5 rows) |
| |
| -- unnest a 2D array: |
| CREATE OR REPLACE FUNCTION unnest2(anyarray) |
| RETURNS SETOF anyelement AS $$ |
| select $1[i][j] |
| from generate_subscripts($1,1) g1(i), |
| generate_subscripts($1,2) g2(j); |
| $$ LANGUAGE sql IMMUTABLE; |
| CREATE FUNCTION |
| SELECT * FROM unnest2(ARRAY[[1,2],[3,4]]); |
| unnest2 |
| --------- |
| 1 |
| 2 |
| 3 |
| 4 |
| (4 rows) |
| </programlisting> |
| </para> |
| |
| <indexterm> |
| <primary>ordinality</primary> |
| </indexterm> |
| |
| <para> |
| When a function in the <literal>FROM</literal> clause is suffixed |
| by <literal>WITH ORDINALITY</literal>, a <type>bigint</type> column is |
| appended to the function's output column(s), which starts from 1 and |
| increments by 1 for each row of the function's output. |
| This is most useful in the case of set returning |
| functions such as <function>unnest()</function>. |
| |
| <programlisting> |
| -- set returning function WITH ORDINALITY: |
| SELECT * FROM pg_ls_dir('.') WITH ORDINALITY AS t(ls,n); |
| ls | n |
| -----------------+---- |
| pg_serial | 1 |
| pg_twophase | 2 |
| postmaster.opts | 3 |
| pg_notify | 4 |
| postgresql.conf | 5 |
| pg_tblspc | 6 |
| logfile | 7 |
| base | 8 |
| postmaster.pid | 9 |
| pg_ident.conf | 10 |
| global | 11 |
| pg_xact | 12 |
| pg_snapshots | 13 |
| pg_multixact | 14 |
| PG_VERSION | 15 |
| pg_wal | 16 |
| pg_hba.conf | 17 |
| pg_stat_tmp | 18 |
| pg_subtrans | 19 |
| (19 rows) |
| </programlisting> |
| </para> |
| |
| </sect1> |
| |
| <sect1 id="functions-info"> |
| <title>System Information Functions and Operators</title> |
| |
| <para> |
| <xref linkend="functions-info-session-table"/> shows several |
| functions that extract session and system information. |
| </para> |
| |
| <para> |
| In addition to the functions listed in this section, there are a number of |
| functions related to the statistics system that also provide system |
| information. See <xref linkend="monitoring-stats-views"/> for more |
| information. |
| </para> |
| |
| <table id="functions-info-session-table"> |
| <title>Session Information Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>current_catalog</primary> |
| </indexterm> |
| <function>current_catalog</function> |
| <returnvalue>name</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <indexterm> |
| <primary>current_database</primary> |
| </indexterm> |
| <function>current_database</function> () |
| <returnvalue>name</returnvalue> |
| </para> |
| <para> |
| Returns the name of the current database. (Databases are |
| called <quote>catalogs</quote> in the SQL standard, |
| so <function>current_catalog</function> is the standard's |
| spelling.) |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>current_query</primary> |
| </indexterm> |
| <function>current_query</function> () |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Returns the text of the currently executing query, as submitted |
| by the client (which might contain more than one statement). |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>current_role</primary> |
| </indexterm> |
| <function>current_role</function> |
| <returnvalue>name</returnvalue> |
| </para> |
| <para> |
| This is equivalent to <function>current_user</function>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>current_schema</primary> |
| </indexterm> |
| <indexterm> |
| <primary>schema</primary> |
| <secondary>current</secondary> |
| </indexterm> |
| <function>current_schema</function> |
| <returnvalue>name</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>current_schema</function> () |
| <returnvalue>name</returnvalue> |
| </para> |
| <para> |
| Returns the name of the schema that is first in the search path (or a |
| null value 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. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>current_schemas</primary> |
| </indexterm> |
| <indexterm> |
| <primary>search path</primary> |
| <secondary>current</secondary> |
| </indexterm> |
| <function>current_schemas</function> ( <parameter>include_implicit</parameter> <type>boolean</type> ) |
| <returnvalue>name[]</returnvalue> |
| </para> |
| <para> |
| Returns an array of the names of all schemas presently in the |
| effective search path, in their priority order. (Items in the current |
| <xref linkend="guc-search-path"/> setting that do not correspond to |
| existing, searchable schemas are omitted.) If the Boolean argument |
| is <literal>true</literal>, then implicitly-searched system schemas |
| such as <literal>pg_catalog</literal> are included in the result. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>current_user</primary> |
| </indexterm> |
| <indexterm> |
| <primary>user</primary> |
| <secondary>current</secondary> |
| </indexterm> |
| <function>current_user</function> |
| <returnvalue>name</returnvalue> |
| </para> |
| <para> |
| Returns the user name of the current execution context. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>inet_client_addr</primary> |
| </indexterm> |
| <function>inet_client_addr</function> () |
| <returnvalue>inet</returnvalue> |
| </para> |
| <para> |
| Returns the IP address of the current client, |
| or <literal>NULL</literal> if the current connection is via a |
| Unix-domain socket. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>inet_client_port</primary> |
| </indexterm> |
| <function>inet_client_port</function> () |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns the IP port number of the current client, |
| or <literal>NULL</literal> if the current connection is via a |
| Unix-domain socket. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>inet_server_addr</primary> |
| </indexterm> |
| <function>inet_server_addr</function> () |
| <returnvalue>inet</returnvalue> |
| </para> |
| <para> |
| Returns the IP address on which the server accepted the current |
| connection, |
| or <literal>NULL</literal> if the current connection is via a |
| Unix-domain socket. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>inet_server_port</primary> |
| </indexterm> |
| <function>inet_server_port</function> () |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns the IP port number on which the server accepted the current |
| connection, |
| or <literal>NULL</literal> if the current connection is via a |
| Unix-domain socket. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_backend_pid</primary> |
| </indexterm> |
| <function>pg_backend_pid</function> () |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns the process ID of the server process attached to the current |
| session. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_blocking_pids</primary> |
| </indexterm> |
| <function>pg_blocking_pids</function> ( <type>integer</type> ) |
| <returnvalue>integer[]</returnvalue> |
| </para> |
| <para> |
| Returns an array of the process ID(s) of the sessions that are |
| blocking the server process with the specified process ID from |
| acquiring a lock, or an empty array if there is no such server process |
| or it is not blocked. |
| </para> |
| <para> |
| One server process blocks another if it either holds a lock that |
| conflicts with the blocked process's lock request (hard block), or is |
| waiting for a lock that would conflict with the blocked process's lock |
| request and is ahead of it in the wait queue (soft block). When using |
| parallel queries the result always lists client-visible process IDs |
| (that is, <function>pg_backend_pid</function> results) even if the |
| actual lock is held or awaited by a child worker process. As a result |
| of that, there may be duplicated PIDs in the result. Also note that |
| when a prepared transaction holds a conflicting lock, it will be |
| represented by a zero process ID. |
| </para> |
| <para> |
| Frequent calls to this function could have some impact on database |
| performance, because it needs exclusive access to the lock manager's |
| shared state for a short time. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_conf_load_time</primary> |
| </indexterm> |
| <function>pg_conf_load_time</function> () |
| <returnvalue>timestamp with time zone</returnvalue> |
| </para> |
| <para> |
| Returns the time when the server configuration files were last loaded. |
| If the current session was alive at the time, this will be the time |
| when the session itself re-read the configuration files (so the |
| reading will vary a little in different sessions). Otherwise it is |
| the time when the postmaster process re-read the configuration files. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_current_logfile</primary> |
| </indexterm> |
| <indexterm> |
| <primary>Logging</primary> |
| <secondary>pg_current_logfile function</secondary> |
| </indexterm> |
| <indexterm> |
| <primary>current_logfiles</primary> |
| <secondary>and the pg_current_logfile function</secondary> |
| </indexterm> |
| <indexterm> |
| <primary>Logging</primary> |
| <secondary>current_logfiles file and the pg_current_logfile |
| function</secondary> |
| </indexterm> |
| <function>pg_current_logfile</function> ( <optional> <type>text</type> </optional> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Returns the path name of the log file currently in use by the logging |
| collector. The path includes the <xref linkend="guc-log-directory"/> |
| directory and the individual log file name. The result |
| is <literal>NULL</literal> if the logging collector is disabled. |
| When multiple log files exist, each in a different |
| format, <function>pg_current_logfile</function> without an argument |
| returns the path of the file having the first format found in the |
| ordered list: <literal>stderr</literal>, |
| <literal>csvlog</literal>. <literal>NULL</literal> is returned |
| if no log file has any of these formats. |
| To request information about a specific log file format, supply |
| either <literal>csvlog</literal> or <literal>stderr</literal> as the |
| value of the optional parameter. The result is <literal>NULL</literal> |
| if the log format requested is not configured in |
| <xref linkend="guc-log-destination"/>. |
| The result reflects the contents of |
| the <filename>current_logfiles</filename> file. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_my_temp_schema</primary> |
| </indexterm> |
| <function>pg_my_temp_schema</function> () |
| <returnvalue>oid</returnvalue> |
| </para> |
| <para> |
| Returns the OID of the current session's temporary schema, or zero if |
| it has none (because it has not created any temporary tables). |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_is_other_temp_schema</primary> |
| </indexterm> |
| <function>pg_is_other_temp_schema</function> ( <type>oid</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Returns true if the given OID is the OID of another session's |
| temporary schema. (This can be useful, for example, to exclude other |
| sessions' temporary tables from a catalog display.) |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_jit_available</primary> |
| </indexterm> |
| <function>pg_jit_available</function> () |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Returns true if a <acronym>JIT</acronym> compiler extension is |
| available (see <xref linkend="jit"/>) and the |
| <xref linkend="guc-jit"/> configuration parameter is set to |
| <literal>on</literal>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_listening_channels</primary> |
| </indexterm> |
| <function>pg_listening_channels</function> () |
| <returnvalue>setof text</returnvalue> |
| </para> |
| <para> |
| Returns the set of names of asynchronous notification channels that |
| the current session is listening to. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_notification_queue_usage</primary> |
| </indexterm> |
| <function>pg_notification_queue_usage</function> () |
| <returnvalue>double precision</returnvalue> |
| </para> |
| <para> |
| Returns the fraction (0–1) of the asynchronous notification |
| queue's maximum size that is currently occupied by notifications that |
| are waiting to be processed. |
| See <xref linkend="sql-listen"/> and <xref linkend="sql-notify"/> |
| for more information. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_postmaster_start_time</primary> |
| </indexterm> |
| <function>pg_postmaster_start_time</function> () |
| <returnvalue>timestamp with time zone</returnvalue> |
| </para> |
| <para> |
| Returns the time when the server started. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_safe_snapshot_blocking_pids</primary> |
| </indexterm> |
| <function>pg_safe_snapshot_blocking_pids</function> ( <type>integer</type> ) |
| <returnvalue>integer[]</returnvalue> |
| </para> |
| <para> |
| Returns an array of the process ID(s) of the sessions that are blocking |
| the server process with the specified process ID from acquiring a safe |
| snapshot, or an empty array if there is no such server process or it |
| is not blocked. |
| </para> |
| <para> |
| A session running a <literal>SERIALIZABLE</literal> transaction blocks |
| a <literal>SERIALIZABLE READ ONLY DEFERRABLE</literal> transaction |
| from acquiring a snapshot until the latter determines that it is safe |
| to avoid taking any predicate locks. See |
| <xref linkend="xact-serializable"/> for more information about |
| serializable and deferrable transactions. |
| </para> |
| <para> |
| Frequent calls to this function could have some impact on database |
| performance, because it needs access to the predicate lock manager's |
| shared state for a short time. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_trigger_depth</primary> |
| </indexterm> |
| <function>pg_trigger_depth</function> () |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns the current nesting level |
| of <productname>PostgreSQL</productname> triggers (0 if not called, |
| directly or indirectly, from inside a trigger). |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>session_user</primary> |
| </indexterm> |
| <function>session_user</function> |
| <returnvalue>name</returnvalue> |
| </para> |
| <para> |
| Returns the session user's name. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>user</primary> |
| </indexterm> |
| <function>user</function> |
| <returnvalue>name</returnvalue> |
| </para> |
| <para> |
| This is equivalent to <function>current_user</function>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>version</primary> |
| </indexterm> |
| <function>version</function> () |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Returns a string describing the <productname>PostgreSQL</productname> |
| server's version. You can also get this information from |
| <xref linkend="guc-server-version"/>, or for a machine-readable |
| version use <xref linkend="guc-server-version-num"/>. Software |
| developers should use <varname>server_version_num</varname> (available |
| since 8.2) or <xref linkend="libpq-PQserverVersion"/> instead of |
| parsing the text version. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <note> |
| <para> |
| <function>current_catalog</function>, |
| <function>current_role</function>, |
| <function>current_schema</function>, |
| <function>current_user</function>, |
| <function>session_user</function>, |
| and <function>user</function> have special syntactic status |
| in <acronym>SQL</acronym>: they must be called without trailing |
| parentheses. In PostgreSQL, parentheses can optionally be used with |
| <function>current_schema</function>, but not with the others. |
| </para> |
| </note> |
| |
| <para> |
| The <function>session_user</function> is normally the user who initiated |
| the current database connection; but superusers can change this setting |
| with <xref linkend="sql-set-session-authorization"/>. |
| The <function>current_user</function> is the user identifier |
| that is applicable for permission checking. Normally it is equal |
| to the session user, but it can be changed with |
| <xref linkend="sql-set-role"/>. |
| It also changes during the execution of |
| functions with the attribute <literal>SECURITY DEFINER</literal>. |
| In Unix parlance, the session user is the <quote>real user</quote> and |
| the current user is the <quote>effective user</quote>. |
| <function>current_role</function> and <function>user</function> are |
| synonyms for <function>current_user</function>. (The SQL standard draws |
| a distinction between <function>current_role</function> |
| and <function>current_user</function>, but <productname>PostgreSQL</productname> |
| does not, since it unifies users and roles into a single kind of entity.) |
| </para> |
| |
| <indexterm> |
| <primary>privilege</primary> |
| <secondary>querying</secondary> |
| </indexterm> |
| |
| <para> |
| <xref linkend="functions-info-access-table"/> lists functions that |
| allow querying object access privileges programmatically. |
| (See <xref linkend="ddl-priv"/> for more information about |
| privileges.) |
| In these functions, the user whose privileges are being inquired about |
| can be specified by name or by OID |
| (<structname>pg_authid</structname>.<structfield>oid</structfield>), or if |
| the name is given as <literal>public</literal> then the privileges of the |
| PUBLIC pseudo-role are checked. Also, the <parameter>user</parameter> |
| argument can be omitted entirely, in which case |
| the <function>current_user</function> is assumed. |
| The object that is being inquired about can be specified either by name or |
| by OID, too. When specifying by name, a schema name can be included if |
| relevant. |
| The access privilege of interest is specified by a text string, which must |
| evaluate to one of the appropriate privilege keywords for the object's type |
| (e.g., <literal>SELECT</literal>). Optionally, <literal>WITH GRANT |
| OPTION</literal> can be added to a privilege type to test whether the |
| privilege is held with grant option. Also, multiple privilege types can be |
| listed separated by commas, in which case the result will be true if any of |
| the listed privileges is held. (Case of the privilege string is not |
| significant, and extra whitespace is allowed between but not within |
| privilege names.) |
| Some examples: |
| <programlisting> |
| SELECT has_table_privilege('myschema.mytable', 'select'); |
| SELECT has_table_privilege('joe', 'mytable', 'INSERT, SELECT WITH GRANT OPTION'); |
| </programlisting> |
| </para> |
| |
| <table id="functions-info-access-table"> |
| <title>Access Privilege Inquiry Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>has_any_column_privilege</primary> |
| </indexterm> |
| <function>has_any_column_privilege</function> ( |
| <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional> |
| <parameter>table</parameter> <type>text</type> or <type>oid</type>, |
| <parameter>privilege</parameter> <type>text</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does user have privilege for any column of table? |
| This succeeds either if the privilege is held for the whole table, or |
| if there is a column-level grant of the privilege for at least one |
| column. |
| Allowable privilege types are |
| <literal>SELECT</literal>, <literal>INSERT</literal>, |
| <literal>UPDATE</literal>, and <literal>REFERENCES</literal>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>has_column_privilege</primary> |
| </indexterm> |
| <function>has_column_privilege</function> ( |
| <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional> |
| <parameter>table</parameter> <type>text</type> or <type>oid</type>, |
| <parameter>column</parameter> <type>text</type> or <type>smallint</type>, |
| <parameter>privilege</parameter> <type>text</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does user have privilege for the specified table column? |
| This succeeds either if the privilege is held for the whole table, or |
| if there is a column-level grant of the privilege for the column. |
| The column can be specified by name or by attribute number |
| (<structname>pg_attribute</structname>.<structfield>attnum</structfield>). |
| Allowable privilege types are |
| <literal>SELECT</literal>, <literal>INSERT</literal>, |
| <literal>UPDATE</literal>, and <literal>REFERENCES</literal>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>has_database_privilege</primary> |
| </indexterm> |
| <function>has_database_privilege</function> ( |
| <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional> |
| <parameter>database</parameter> <type>text</type> or <type>oid</type>, |
| <parameter>privilege</parameter> <type>text</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does user have privilege for database? |
| Allowable privilege types are |
| <literal>CREATE</literal>, |
| <literal>CONNECT</literal>, |
| <literal>TEMPORARY</literal>, and |
| <literal>TEMP</literal> (which is equivalent to |
| <literal>TEMPORARY</literal>). |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>has_foreign_data_wrapper_privilege</primary> |
| </indexterm> |
| <function>has_foreign_data_wrapper_privilege</function> ( |
| <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional> |
| <parameter>fdw</parameter> <type>text</type> or <type>oid</type>, |
| <parameter>privilege</parameter> <type>text</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does user have privilege for foreign-data wrapper? |
| The only allowable privilege type is <literal>USAGE</literal>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>has_function_privilege</primary> |
| </indexterm> |
| <function>has_function_privilege</function> ( |
| <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional> |
| <parameter>function</parameter> <type>text</type> or <type>oid</type>, |
| <parameter>privilege</parameter> <type>text</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does user have privilege for function? |
| The only allowable privilege type is <literal>EXECUTE</literal>. |
| </para> |
| <para> |
| When specifying a function by name rather than by OID, the allowed |
| input is the same as for the <type>regprocedure</type> data type (see |
| <xref linkend="datatype-oid"/>). |
| An example is: |
| <programlisting> |
| SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute'); |
| </programlisting> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>has_language_privilege</primary> |
| </indexterm> |
| <function>has_language_privilege</function> ( |
| <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional> |
| <parameter>language</parameter> <type>text</type> or <type>oid</type>, |
| <parameter>privilege</parameter> <type>text</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does user have privilege for language? |
| The only allowable privilege type is <literal>USAGE</literal>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>has_schema_privilege</primary> |
| </indexterm> |
| <function>has_schema_privilege</function> ( |
| <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional> |
| <parameter>schema</parameter> <type>text</type> or <type>oid</type>, |
| <parameter>privilege</parameter> <type>text</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does user have privilege for schema? |
| Allowable privilege types are |
| <literal>CREATE</literal> and |
| <literal>USAGE</literal>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>has_sequence_privilege</primary> |
| </indexterm> |
| <function>has_sequence_privilege</function> ( |
| <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional> |
| <parameter>sequence</parameter> <type>text</type> or <type>oid</type>, |
| <parameter>privilege</parameter> <type>text</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does user have privilege for sequence? |
| Allowable privilege types are |
| <literal>USAGE</literal>, |
| <literal>SELECT</literal>, and |
| <literal>UPDATE</literal>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>has_server_privilege</primary> |
| </indexterm> |
| <function>has_server_privilege</function> ( |
| <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional> |
| <parameter>server</parameter> <type>text</type> or <type>oid</type>, |
| <parameter>privilege</parameter> <type>text</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does user have privilege for foreign server? |
| The only allowable privilege type is <literal>USAGE</literal>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>has_table_privilege</primary> |
| </indexterm> |
| <function>has_table_privilege</function> ( |
| <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional> |
| <parameter>table</parameter> <type>text</type> or <type>oid</type>, |
| <parameter>privilege</parameter> <type>text</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does user have privilege for table? |
| Allowable privilege types |
| are <literal>SELECT</literal>, <literal>INSERT</literal>, |
| <literal>UPDATE</literal>, <literal>DELETE</literal>, |
| <literal>TRUNCATE</literal>, <literal>REFERENCES</literal>, |
| and <literal>TRIGGER</literal>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>has_tablespace_privilege</primary> |
| </indexterm> |
| <function>has_tablespace_privilege</function> ( |
| <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional> |
| <parameter>tablespace</parameter> <type>text</type> or <type>oid</type>, |
| <parameter>privilege</parameter> <type>text</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does user have privilege for tablespace? |
| The only allowable privilege type is <literal>CREATE</literal>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>has_type_privilege</primary> |
| </indexterm> |
| <function>has_type_privilege</function> ( |
| <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional> |
| <parameter>type</parameter> <type>text</type> or <type>oid</type>, |
| <parameter>privilege</parameter> <type>text</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does user have privilege for data type? |
| The only allowable privilege type is <literal>USAGE</literal>. |
| When specifying a type by name rather than by OID, the allowed input |
| is the same as for the <type>regtype</type> data type (see |
| <xref linkend="datatype-oid"/>). |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_has_role</primary> |
| </indexterm> |
| <function>pg_has_role</function> ( |
| <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional> |
| <parameter>role</parameter> <type>text</type> or <type>oid</type>, |
| <parameter>privilege</parameter> <type>text</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does user have privilege for role? |
| Allowable privilege types are |
| <literal>MEMBER</literal> and <literal>USAGE</literal>. |
| <literal>MEMBER</literal> denotes direct or indirect membership in |
| the role (that is, the right to do <command>SET ROLE</command>), while |
| <literal>USAGE</literal> denotes whether the privileges of the role |
| are immediately available without doing <command>SET ROLE</command>. |
| This function does not allow the special case of |
| setting <parameter>user</parameter> to <literal>public</literal>, |
| because the PUBLIC pseudo-role can never be a member of real roles. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>row_security_active</primary> |
| </indexterm> |
| <function>row_security_active</function> ( |
| <parameter>table</parameter> <type>text</type> or <type>oid</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is row-level security active for the specified table in the context of |
| the current user and current environment? |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| <xref linkend="functions-aclitem-op-table"/> shows the operators |
| available for the <type>aclitem</type> type, which is the catalog |
| representation of access privileges. See <xref linkend="ddl-priv"/> |
| for information about how to read access privilege values. |
| </para> |
| |
| <table id="functions-aclitem-op-table"> |
| <title><type>aclitem</type> Operators</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Operator |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>aclitemeq</primary> |
| </indexterm> |
| <type>aclitem</type> <literal>=</literal> <type>aclitem</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Are <type>aclitem</type>s equal? (Notice that |
| type <type>aclitem</type> lacks the usual set of comparison |
| operators; it has only equality. In turn, <type>aclitem</type> |
| arrays can only be compared for equality.) |
| </para> |
| <para> |
| <literal>'calvin=r*w/hobbes'::aclitem = 'calvin=r*w*/hobbes'::aclitem</literal> |
| <returnvalue>f</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>aclcontains</primary> |
| </indexterm> |
| <type>aclitem[]</type> <literal>@></literal> <type>aclitem</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Does array contain the specified privileges? (This is true if there |
| is an array entry that matches the <type>aclitem</type>'s grantee and |
| grantor, and has at least the specified set of privileges.) |
| </para> |
| <para> |
| <literal>'{calvin=r*w/hobbes,hobbes=r*w*/postgres}'::aclitem[] @> 'calvin=r*/hobbes'::aclitem</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <type>aclitem[]</type> <literal>~</literal> <type>aclitem</type> |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| This is a deprecated alias for <literal>@></literal>. |
| </para> |
| <para> |
| <literal>'{calvin=r*w/hobbes,hobbes=r*w*/postgres}'::aclitem[] ~ 'calvin=r*/hobbes'::aclitem</literal> |
| <returnvalue>t</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| <xref linkend="functions-aclitem-fn-table"/> shows some additional |
| functions to manage the <type>aclitem</type> type. |
| </para> |
| |
| <table id="functions-aclitem-fn-table"> |
| <title><type>aclitem</type> Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>acldefault</primary> |
| </indexterm> |
| <function>acldefault</function> ( |
| <parameter>type</parameter> <type>"char"</type>, |
| <parameter>ownerId</parameter> <type>oid</type> ) |
| <returnvalue>aclitem[]</returnvalue> |
| </para> |
| <para> |
| Constructs an <type>aclitem</type> array holding the default access |
| privileges for an object of type <parameter>type</parameter> belonging |
| to the role with OID <parameter>ownerId</parameter>. This represents |
| the access privileges that will be assumed when an object's ACL entry |
| is null. (The default access privileges are described in |
| <xref linkend="ddl-priv"/>.) |
| The <parameter>type</parameter> parameter must be one of |
| 'c' for <literal>COLUMN</literal>, |
| 'r' for <literal>TABLE</literal> and table-like objects, |
| 's' for <literal>SEQUENCE</literal>, |
| 'd' for <literal>DATABASE</literal>, |
| 'f' for <literal>FUNCTION</literal> or <literal>PROCEDURE</literal>, |
| 'l' for <literal>LANGUAGE</literal>, |
| 'L' for <literal>LARGE OBJECT</literal>, |
| 'n' for <literal>SCHEMA</literal>, |
| 't' for <literal>TABLESPACE</literal>, |
| 'F' for <literal>FOREIGN DATA WRAPPER</literal>, |
| 'S' for <literal>FOREIGN SERVER</literal>, |
| or |
| 'T' for <literal>TYPE</literal> or <literal>DOMAIN</literal>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>aclexplode</primary> |
| </indexterm> |
| <function>aclexplode</function> ( <type>aclitem[]</type> ) |
| <returnvalue>setof record</returnvalue> |
| ( <parameter>grantor</parameter> <type>oid</type>, |
| <parameter>grantee</parameter> <type>oid</type>, |
| <parameter>privilege_type</parameter> <type>text</type>, |
| <parameter>is_grantable</parameter> <type>boolean</type> ) |
| </para> |
| <para> |
| Returns the <type>aclitem</type> array as a set of rows. |
| If the grantee is the pseudo-role PUBLIC, it is represented by zero in |
| the <parameter>grantee</parameter> column. Each granted privilege is |
| represented as <literal>SELECT</literal>, <literal>INSERT</literal>, |
| etc. Note that each privilege is broken out as a separate row, so |
| only one keyword appears in the <parameter>privilege_type</parameter> |
| column. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>makeaclitem</primary> |
| </indexterm> |
| <function>makeaclitem</function> ( |
| <parameter>grantee</parameter> <type>oid</type>, |
| <parameter>grantor</parameter> <type>oid</type>, |
| <parameter>privileges</parameter> <type>text</type>, |
| <parameter>is_grantable</parameter> <type>boolean</type> ) |
| <returnvalue>aclitem</returnvalue> |
| </para> |
| <para> |
| Constructs an <type>aclitem</type> with the given properties. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| <xref linkend="functions-info-schema-table"/> shows functions that |
| determine whether a certain object is <firstterm>visible</firstterm> in the |
| current schema search path. |
| For example, a table is said to be visible if its |
| containing schema is in the search path and no table of the same |
| name appears earlier in the search path. This is equivalent to the |
| statement that the table can be referenced by name without explicit |
| schema qualification. Thus, to list the names of all visible tables: |
| <programlisting> |
| SELECT relname FROM pg_class WHERE pg_table_is_visible(oid); |
| </programlisting> |
| For functions and operators, an object in the search path is said to be |
| visible if there is no object of the same name <emphasis>and argument data |
| type(s)</emphasis> earlier in the path. For operator classes and families, |
| both the name and the associated index access method are considered. |
| </para> |
| |
| <indexterm> |
| <primary>search path</primary> |
| <secondary>object visibility</secondary> |
| </indexterm> |
| |
| <table id="functions-info-schema-table"> |
| <title>Schema Visibility Inquiry Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_collation_is_visible</primary> |
| </indexterm> |
| <function>pg_collation_is_visible</function> ( <parameter>collation</parameter> <type>oid</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is collation visible in search path? |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_conversion_is_visible</primary> |
| </indexterm> |
| <function>pg_conversion_is_visible</function> ( <parameter>conversion</parameter> <type>oid</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is conversion visible in search path? |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_function_is_visible</primary> |
| </indexterm> |
| <function>pg_function_is_visible</function> ( <parameter>function</parameter> <type>oid</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is function visible in search path? |
| (This also works for procedures and aggregates.) |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_opclass_is_visible</primary> |
| </indexterm> |
| <function>pg_opclass_is_visible</function> ( <parameter>opclass</parameter> <type>oid</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is operator class visible in search path? |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_operator_is_visible</primary> |
| </indexterm> |
| <function>pg_operator_is_visible</function> ( <parameter>operator</parameter> <type>oid</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is operator visible in search path? |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_opfamily_is_visible</primary> |
| </indexterm> |
| <function>pg_opfamily_is_visible</function> ( <parameter>opclass</parameter> <type>oid</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is operator family visible in search path? |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_statistics_obj_is_visible</primary> |
| </indexterm> |
| <function>pg_statistics_obj_is_visible</function> ( <parameter>stat</parameter> <type>oid</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is statistics object visible in search path? |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_table_is_visible</primary> |
| </indexterm> |
| <function>pg_table_is_visible</function> ( <parameter>table</parameter> <type>oid</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is table visible in search path? |
| (This works for all types of relations, including views, materialized |
| views, indexes, sequences and foreign tables.) |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_ts_config_is_visible</primary> |
| </indexterm> |
| <function>pg_ts_config_is_visible</function> ( <parameter>config</parameter> <type>oid</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is text search configuration visible in search path? |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_ts_dict_is_visible</primary> |
| </indexterm> |
| <function>pg_ts_dict_is_visible</function> ( <parameter>dict</parameter> <type>oid</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is text search dictionary visible in search path? |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_ts_parser_is_visible</primary> |
| </indexterm> |
| <function>pg_ts_parser_is_visible</function> ( <parameter>parser</parameter> <type>oid</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is text search parser visible in search path? |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_ts_template_is_visible</primary> |
| </indexterm> |
| <function>pg_ts_template_is_visible</function> ( <parameter>template</parameter> <type>oid</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is text search template visible in search path? |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_type_is_visible</primary> |
| </indexterm> |
| <function>pg_type_is_visible</function> ( <parameter>type</parameter> <type>oid</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is type (or domain) visible in search path? |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| All these functions require object OIDs to identify the object to be |
| checked. If you want to test an object by name, it is convenient to use |
| the OID alias types (<type>regclass</type>, <type>regtype</type>, |
| <type>regprocedure</type>, <type>regoperator</type>, <type>regconfig</type>, |
| or <type>regdictionary</type>), |
| for example: |
| <programlisting> |
| SELECT pg_type_is_visible('myschema.widget'::regtype); |
| </programlisting> |
| Note that it would not make much sense to test a non-schema-qualified |
| type name in this way — if the name can be recognized at all, it must be visible. |
| </para> |
| |
| <para> |
| <xref linkend="functions-info-catalog-table"/> lists functions that |
| extract information from the system catalogs. |
| </para> |
| |
| <table id="functions-info-catalog-table"> |
| <title>System Catalog Information Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>format_type</primary> |
| </indexterm> |
| <function>format_type</function> ( <parameter>type</parameter> <type>oid</type>, <parameter>typemod</parameter> <type>integer</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Returns the SQL name for a data type that is identified by its type |
| OID and possibly a type modifier. Pass NULL for the type modifier if |
| no specific modifier is known. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_get_catalog_foreign_keys</primary> |
| </indexterm> |
| <function>pg_get_catalog_foreign_keys</function> () |
| <returnvalue>setof record</returnvalue> |
| ( <parameter>fktable</parameter> <type>regclass</type>, |
| <parameter>fkcols</parameter> <type>text[]</type>, |
| <parameter>pktable</parameter> <type>regclass</type>, |
| <parameter>pkcols</parameter> <type>text[]</type>, |
| <parameter>is_array</parameter> <type>boolean</type>, |
| <parameter>is_opt</parameter> <type>boolean</type> ) |
| </para> |
| <para> |
| Returns a set of records describing the foreign key relationships |
| that exist within the <productname>PostgreSQL</productname> system |
| catalogs. |
| The <parameter>fktable</parameter> column contains the name of the |
| referencing catalog, and the <parameter>fkcols</parameter> column |
| contains the name(s) of the referencing column(s). Similarly, |
| the <parameter>pktable</parameter> column contains the name of the |
| referenced catalog, and the <parameter>pkcols</parameter> column |
| contains the name(s) of the referenced column(s). |
| If <parameter>is_array</parameter> is true, the last referencing |
| column is an array, each of whose elements should match some entry |
| in the referenced catalog. |
| If <parameter>is_opt</parameter> is true, the referencing column(s) |
| are allowed to contain zeroes instead of a valid reference. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_get_constraintdef</primary> |
| </indexterm> |
| <function>pg_get_constraintdef</function> ( <parameter>constraint</parameter> <type>oid</type> <optional>, <parameter>pretty</parameter> <type>boolean</type> </optional> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Reconstructs the creating command for a constraint. |
| (This is a decompiled reconstruction, not the original text |
| of the command.) |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_get_expr</primary> |
| </indexterm> |
| <function>pg_get_expr</function> ( <parameter>expr</parameter> <type>pg_node_tree</type>, <parameter>relation</parameter> <type>oid</type> <optional>, <parameter>pretty</parameter> <type>boolean</type> </optional> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Decompiles the internal form of an expression stored in the system |
| catalogs, such as the default value for a column. If the expression |
| might contain Vars, specify the OID of the relation they refer to as |
| the second parameter; if no Vars are expected, passing zero is |
| sufficient. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_get_functiondef</primary> |
| </indexterm> |
| <function>pg_get_functiondef</function> ( <parameter>func</parameter> <type>oid</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Reconstructs the creating command for a function or procedure. |
| (This is a decompiled reconstruction, not the original text |
| of the command.) |
| The result is a complete <command>CREATE OR REPLACE FUNCTION</command> |
| or <command>CREATE OR REPLACE PROCEDURE</command> statement. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_get_function_arguments</primary> |
| </indexterm> |
| <function>pg_get_function_arguments</function> ( <parameter>func</parameter> <type>oid</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Reconstructs the argument list of a function or procedure, in the form |
| it would need to appear in within <command>CREATE FUNCTION</command> |
| (including default values). |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_get_function_identity_arguments</primary> |
| </indexterm> |
| <function>pg_get_function_identity_arguments</function> ( <parameter>func</parameter> <type>oid</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Reconstructs the argument list necessary to identify a function or |
| procedure, in the form it would need to appear in within commands such |
| as <command>ALTER FUNCTION</command>. This form omits default values. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_get_function_result</primary> |
| </indexterm> |
| <function>pg_get_function_result</function> ( <parameter>func</parameter> <type>oid</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Reconstructs the <literal>RETURNS</literal> clause of a function, in |
| the form it would need to appear in within <command>CREATE |
| FUNCTION</command>. Returns <literal>NULL</literal> for a procedure. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_get_indexdef</primary> |
| </indexterm> |
| <function>pg_get_indexdef</function> ( <parameter>index</parameter> <type>oid</type> <optional>, <parameter>column</parameter> <type>integer</type>, <parameter>pretty</parameter> <type>boolean</type> </optional> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Reconstructs the creating command for an index. |
| (This is a decompiled reconstruction, not the original text |
| of the command.) If <parameter>column</parameter> is supplied and is |
| not zero, only the definition of that column is reconstructed. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_get_keywords</primary> |
| </indexterm> |
| <function>pg_get_keywords</function> () |
| <returnvalue>setof record</returnvalue> |
| ( <parameter>word</parameter> <type>text</type>, |
| <parameter>catcode</parameter> <type>"char"</type>, |
| <parameter>barelabel</parameter> <type>boolean</type>, |
| <parameter>catdesc</parameter> <type>text</type>, |
| <parameter>baredesc</parameter> <type>text</type> ) |
| </para> |
| <para> |
| Returns a set of records describing the SQL keywords recognized by the |
| server. The <parameter>word</parameter> column contains the |
| keyword. The <parameter>catcode</parameter> column contains a |
| category code: <literal>U</literal> for an unreserved |
| keyword, <literal>C</literal> for a keyword that can be a column |
| name, <literal>T</literal> for a keyword that can be a type or |
| function name, or <literal>R</literal> for a fully reserved keyword. |
| The <parameter>barelabel</parameter> column |
| contains <literal>true</literal> if the keyword can be used as |
| a <quote>bare</quote> column label in <command>SELECT</command> lists, |
| or <literal>false</literal> if it can only be used |
| after <literal>AS</literal>. |
| The <parameter>catdesc</parameter> column contains a |
| possibly-localized string describing the keyword's category. |
| The <parameter>baredesc</parameter> column contains a |
| possibly-localized string describing the keyword's column label status. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_get_ruledef</primary> |
| </indexterm> |
| <function>pg_get_ruledef</function> ( <parameter>rule</parameter> <type>oid</type> <optional>, <parameter>pretty</parameter> <type>boolean</type> </optional> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Reconstructs the creating command for a rule. |
| (This is a decompiled reconstruction, not the original text |
| of the command.) |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_get_serial_sequence</primary> |
| </indexterm> |
| <function>pg_get_serial_sequence</function> ( <parameter>table</parameter> <type>text</type>, <parameter>column</parameter> <type>text</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Returns the name of the sequence associated with a column, |
| or NULL if no sequence is associated with the column. |
| If the column is an identity column, the associated sequence is the |
| sequence internally created for that column. |
| For columns created using one of the serial types |
| (<type>serial</type>, <type>smallserial</type>, <type>bigserial</type>), |
| it is the sequence created for that serial column definition. |
| In the latter case, the association can be modified or removed |
| with <command>ALTER SEQUENCE OWNED BY</command>. |
| (This function probably should have been |
| called <function>pg_get_owned_sequence</function>; its current name |
| reflects the fact that it has historically been used with serial-type |
| columns.) The first parameter is a table name with optional |
| schema, and the second parameter is a column name. Because the first |
| parameter potentially contains both schema and table names, it is |
| parsed per usual SQL rules, meaning it is lower-cased by default. |
| The second parameter, being just a column name, is treated literally |
| and so has its case preserved. The result is suitably formatted |
| for passing to the sequence functions (see |
| <xref linkend="functions-sequence"/>). |
| </para> |
| <para> |
| A typical use is in reading the current value of the sequence for an |
| identity or serial column, for example: |
| <programlisting> |
| SELECT currval(pg_get_serial_sequence('sometable', 'id')); |
| </programlisting> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_get_statisticsobjdef</primary> |
| </indexterm> |
| <function>pg_get_statisticsobjdef</function> ( <parameter>statobj</parameter> <type>oid</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Reconstructs the creating command for an extended statistics object. |
| (This is a decompiled reconstruction, not the original text |
| of the command.) |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_get_triggerdef</primary> |
| </indexterm> |
| <function>pg_get_triggerdef</function> ( <parameter>trigger</parameter> <type>oid</type> <optional>, <parameter>pretty</parameter> <type>boolean</type> </optional> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Reconstructs the creating command for a trigger. |
| (This is a decompiled reconstruction, not the original text |
| of the command.) |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_get_userbyid</primary> |
| </indexterm> |
| <function>pg_get_userbyid</function> ( <parameter>role</parameter> <type>oid</type> ) |
| <returnvalue>name</returnvalue> |
| </para> |
| <para> |
| Returns a role's name given its OID. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_get_viewdef</primary> |
| </indexterm> |
| <function>pg_get_viewdef</function> ( <parameter>view</parameter> <type>oid</type> <optional>, <parameter>pretty</parameter> <type>boolean</type> </optional> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Reconstructs the underlying <command>SELECT</command> command for a |
| view or materialized view. (This is a decompiled reconstruction, not |
| the original text of the command.) |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>pg_get_viewdef</function> ( <parameter>view</parameter> <type>oid</type>, <parameter>wrap_column</parameter> <type>integer</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Reconstructs the underlying <command>SELECT</command> command for a |
| view or materialized view. (This is a decompiled reconstruction, not |
| the original text of the command.) In this form of the function, |
| pretty-printing is always enabled, and long lines are wrapped to try |
| to keep them shorter than the specified number of columns. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>pg_get_viewdef</function> ( <parameter>view</parameter> <type>text</type> <optional>, <parameter>pretty</parameter> <type>boolean</type> </optional> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Reconstructs the underlying <command>SELECT</command> command for a |
| view or materialized view, working from a textual name for the view |
| rather than its OID. (This is deprecated; use the OID variant |
| instead.) |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_index_column_has_property</primary> |
| </indexterm> |
| <function>pg_index_column_has_property</function> ( <parameter>index</parameter> <type>regclass</type>, <parameter>column</parameter> <type>integer</type>, <parameter>property</parameter> <type>text</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Tests whether an index column has the named property. |
| Common index column properties are listed in |
| <xref linkend="functions-info-index-column-props"/>. |
| (Note that extension access methods can define additional property |
| names for their indexes.) |
| <literal>NULL</literal> is returned if the property name is not known |
| or does not apply to the particular object, or if the OID or column |
| number does not identify a valid object. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_index_has_property</primary> |
| </indexterm> |
| <function>pg_index_has_property</function> ( <parameter>index</parameter> <type>regclass</type>, <parameter>property</parameter> <type>text</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Tests whether an index has the named property. |
| Common index properties are listed in |
| <xref linkend="functions-info-index-props"/>. |
| (Note that extension access methods can define additional property |
| names for their indexes.) |
| <literal>NULL</literal> is returned if the property name is not known |
| or does not apply to the particular object, or if the OID does not |
| identify a valid object. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_indexam_has_property</primary> |
| </indexterm> |
| <function>pg_indexam_has_property</function> ( <parameter>am</parameter> <type>oid</type>, <parameter>property</parameter> <type>text</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Tests whether an index access method has the named property. |
| Access method properties are listed in |
| <xref linkend="functions-info-indexam-props"/>. |
| <literal>NULL</literal> is returned if the property name is not known |
| or does not apply to the particular object, or if the OID does not |
| identify a valid object. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_options_to_table</primary> |
| </indexterm> |
| <function>pg_options_to_table</function> ( <parameter>options_array</parameter> <type>text[]</type> ) |
| <returnvalue>setof record</returnvalue> |
| ( <parameter>option_name</parameter> <type>text</type>, |
| <parameter>option_value</parameter> <type>text</type> ) |
| </para> |
| <para> |
| Returns the set of storage options represented by a value from |
| <structname>pg_class</structname>.<structfield>reloptions</structfield> or |
| <structname>pg_attribute</structname>.<structfield>attoptions</structfield>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_tablespace_databases</primary> |
| </indexterm> |
| <function>pg_tablespace_databases</function> ( <parameter>tablespace</parameter> <type>oid</type> ) |
| <returnvalue>setof oid</returnvalue> |
| </para> |
| <para> |
| Returns the set of OIDs of databases that have objects stored in the |
| specified tablespace. If this function returns any rows, the |
| tablespace is not empty and cannot be dropped. To identify the specific |
| objects populating the tablespace, you will need to connect to the |
| database(s) identified by <function>pg_tablespace_databases</function> |
| and query their <structname>pg_class</structname> catalogs. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_tablespace_location</primary> |
| </indexterm> |
| <function>pg_tablespace_location</function> ( <parameter>tablespace</parameter> <type>oid</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Returns the file system path that this tablespace is located in. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_typeof</primary> |
| </indexterm> |
| <function>pg_typeof</function> ( <type>"any"</type> ) |
| <returnvalue>regtype</returnvalue> |
| </para> |
| <para> |
| Returns the OID of the data type of the value that is passed to it. |
| This can be helpful for troubleshooting or dynamically constructing |
| SQL queries. The function is declared as |
| returning <type>regtype</type>, which is an OID alias type (see |
| <xref linkend="datatype-oid"/>); this means that it is the same as an |
| OID for comparison purposes but displays as a type name. |
| </para> |
| <para> |
| For example: |
| <programlisting> |
| SELECT pg_typeof(33); |
| pg_typeof |
| ----------- |
| integer |
| |
| SELECT typlen FROM pg_type WHERE oid = pg_typeof(33); |
| typlen |
| -------- |
| 4 |
| </programlisting> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>COLLATION FOR</primary> |
| </indexterm> |
| <function>COLLATION FOR</function> ( <type>"any"</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Returns the name of the collation of the value that is passed to it. |
| The value is quoted and schema-qualified if necessary. If no |
| collation was derived for the argument expression, |
| then <literal>NULL</literal> is returned. If the argument is not of a |
| collatable data type, then an error is raised. |
| </para> |
| <para> |
| For example: |
| <programlisting> |
| SELECT collation for (description) FROM pg_description LIMIT 1; |
| pg_collation_for |
| ------------------ |
| "default" |
| |
| SELECT collation for ('foo' COLLATE "de_DE"); |
| pg_collation_for |
| ------------------ |
| "de_DE" |
| </programlisting> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>to_regclass</primary> |
| </indexterm> |
| <function>to_regclass</function> ( <type>text</type> ) |
| <returnvalue>regclass</returnvalue> |
| </para> |
| <para> |
| Translates a textual relation name to its OID. A similar result is |
| obtained by casting the string to type <type>regclass</type> (see |
| <xref linkend="datatype-oid"/>); however, this function will return |
| <literal>NULL</literal> rather than throwing an error if the name is |
| not found. Also unlike the cast, this does not accept |
| a numeric OID as input. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>to_regcollation</primary> |
| </indexterm> |
| <function>to_regcollation</function> ( <type>text</type> ) |
| <returnvalue>regcollation</returnvalue> |
| </para> |
| <para> |
| Translates a textual collation name to its OID. A similar result is |
| obtained by casting the string to type <type>regcollation</type> (see |
| <xref linkend="datatype-oid"/>); however, this function will return |
| <literal>NULL</literal> rather than throwing an error if the name is |
| not found. Also unlike the cast, this does not accept |
| a numeric OID as input. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>to_regnamespace</primary> |
| </indexterm> |
| <function>to_regnamespace</function> ( <type>text</type> ) |
| <returnvalue>regnamespace</returnvalue> |
| </para> |
| <para> |
| Translates a textual schema name to its OID. A similar result is |
| obtained by casting the string to type <type>regnamespace</type> (see |
| <xref linkend="datatype-oid"/>); however, this function will return |
| <literal>NULL</literal> rather than throwing an error if the name is |
| not found. Also unlike the cast, this does not accept |
| a numeric OID as input. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>to_regoper</primary> |
| </indexterm> |
| <function>to_regoper</function> ( <type>text</type> ) |
| <returnvalue>regoper</returnvalue> |
| </para> |
| <para> |
| Translates a textual operator name to its OID. A similar result is |
| obtained by casting the string to type <type>regoper</type> (see |
| <xref linkend="datatype-oid"/>); however, this function will return |
| <literal>NULL</literal> rather than throwing an error if the name is |
| not found or is ambiguous. Also unlike the cast, this does not accept |
| a numeric OID as input. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>to_regoperator</primary> |
| </indexterm> |
| <function>to_regoperator</function> ( <type>text</type> ) |
| <returnvalue>regoperator</returnvalue> |
| </para> |
| <para> |
| Translates a textual operator name (with parameter types) to its OID. A similar result is |
| obtained by casting the string to type <type>regoperator</type> (see |
| <xref linkend="datatype-oid"/>); however, this function will return |
| <literal>NULL</literal> rather than throwing an error if the name is |
| not found. Also unlike the cast, this does not accept |
| a numeric OID as input. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>to_regproc</primary> |
| </indexterm> |
| <function>to_regproc</function> ( <type>text</type> ) |
| <returnvalue>regproc</returnvalue> |
| </para> |
| <para> |
| Translates a textual function or procedure name to its OID. A similar result is |
| obtained by casting the string to type <type>regproc</type> (see |
| <xref linkend="datatype-oid"/>); however, this function will return |
| <literal>NULL</literal> rather than throwing an error if the name is |
| not found or is ambiguous. Also unlike the cast, this does not accept |
| a numeric OID as input. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>to_regprocedure</primary> |
| </indexterm> |
| <function>to_regprocedure</function> ( <type>text</type> ) |
| <returnvalue>regprocedure</returnvalue> |
| </para> |
| <para> |
| Translates a textual function or procedure name (with argument types) to its OID. A similar result is |
| obtained by casting the string to type <type>regprocedure</type> (see |
| <xref linkend="datatype-oid"/>); however, this function will return |
| <literal>NULL</literal> rather than throwing an error if the name is |
| not found. Also unlike the cast, this does not accept |
| a numeric OID as input. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>to_regrole</primary> |
| </indexterm> |
| <function>to_regrole</function> ( <type>text</type> ) |
| <returnvalue>regrole</returnvalue> |
| </para> |
| <para> |
| Translates a textual role name to its OID. A similar result is |
| obtained by casting the string to type <type>regrole</type> (see |
| <xref linkend="datatype-oid"/>); however, this function will return |
| <literal>NULL</literal> rather than throwing an error if the name is |
| not found. Also unlike the cast, this does not accept |
| a numeric OID as input. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>to_regtype</primary> |
| </indexterm> |
| <function>to_regtype</function> ( <type>text</type> ) |
| <returnvalue>regtype</returnvalue> |
| </para> |
| <para> |
| Translates a textual type name to its OID. A similar result is |
| obtained by casting the string to type <type>regtype</type> (see |
| <xref linkend="datatype-oid"/>); however, this function will return |
| <literal>NULL</literal> rather than throwing an error if the name is |
| not found. Also unlike the cast, this does not accept |
| a numeric OID as input. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| Most of the functions that reconstruct (decompile) database objects |
| have an optional <parameter>pretty</parameter> flag, which |
| if <literal>true</literal> causes the result to |
| be <quote>pretty-printed</quote>. Pretty-printing suppresses unnecessary |
| parentheses and adds whitespace for legibility. |
| The pretty-printed format is more readable, but the default format |
| is more likely to be interpreted the same way by future versions of |
| <productname>PostgreSQL</productname>; so avoid using pretty-printed output |
| for dump purposes. Passing <literal>false</literal> for |
| the <parameter>pretty</parameter> parameter yields the same result as |
| omitting the parameter. |
| </para> |
| |
| <table id="functions-info-index-column-props"> |
| <title>Index Column Properties</title> |
| <tgroup cols="2"> |
| <thead> |
| <row><entry>Name</entry><entry>Description</entry></row> |
| </thead> |
| <tbody> |
| <row> |
| <entry><literal>asc</literal></entry> |
| <entry>Does the column sort in ascending order on a forward scan? |
| </entry> |
| </row> |
| <row> |
| <entry><literal>desc</literal></entry> |
| <entry>Does the column sort in descending order on a forward scan? |
| </entry> |
| </row> |
| <row> |
| <entry><literal>nulls_first</literal></entry> |
| <entry>Does the column sort with nulls first on a forward scan? |
| </entry> |
| </row> |
| <row> |
| <entry><literal>nulls_last</literal></entry> |
| <entry>Does the column sort with nulls last on a forward scan? |
| </entry> |
| </row> |
| <row> |
| <entry><literal>orderable</literal></entry> |
| <entry>Does the column possess any defined sort ordering? |
| </entry> |
| </row> |
| <row> |
| <entry><literal>distance_orderable</literal></entry> |
| <entry>Can the column be scanned in order by a <quote>distance</quote> |
| operator, for example <literal>ORDER BY col <-> constant</literal> ? |
| </entry> |
| </row> |
| <row> |
| <entry><literal>returnable</literal></entry> |
| <entry>Can the column value be returned by an index-only scan? |
| </entry> |
| </row> |
| <row> |
| <entry><literal>search_array</literal></entry> |
| <entry>Does the column natively support <literal>col = ANY(array)</literal> |
| searches? |
| </entry> |
| </row> |
| <row> |
| <entry><literal>search_nulls</literal></entry> |
| <entry>Does the column support <literal>IS NULL</literal> and |
| <literal>IS NOT NULL</literal> searches? |
| </entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <table id="functions-info-index-props"> |
| <title>Index Properties</title> |
| <tgroup cols="2"> |
| <thead> |
| <row><entry>Name</entry><entry>Description</entry></row> |
| </thead> |
| <tbody> |
| <row> |
| <entry><literal>clusterable</literal></entry> |
| <entry>Can the index be used in a <literal>CLUSTER</literal> command? |
| </entry> |
| </row> |
| <row> |
| <entry><literal>index_scan</literal></entry> |
| <entry>Does the index support plain (non-bitmap) scans? |
| </entry> |
| </row> |
| <row> |
| <entry><literal>bitmap_scan</literal></entry> |
| <entry>Does the index support bitmap scans? |
| </entry> |
| </row> |
| <row> |
| <entry><literal>backward_scan</literal></entry> |
| <entry>Can the scan direction be changed in mid-scan (to |
| support <literal>FETCH BACKWARD</literal> on a cursor without |
| needing materialization)? |
| </entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <table id="functions-info-indexam-props"> |
| <title>Index Access Method Properties</title> |
| <tgroup cols="2"> |
| <thead> |
| <row><entry>Name</entry><entry>Description</entry></row> |
| </thead> |
| <tbody> |
| <row> |
| <entry><literal>can_order</literal></entry> |
| <entry>Does the access method support <literal>ASC</literal>, |
| <literal>DESC</literal> and related keywords in |
| <literal>CREATE INDEX</literal>? |
| </entry> |
| </row> |
| <row> |
| <entry><literal>can_unique</literal></entry> |
| <entry>Does the access method support unique indexes? |
| </entry> |
| </row> |
| <row> |
| <entry><literal>can_multi_col</literal></entry> |
| <entry>Does the access method support indexes with multiple columns? |
| </entry> |
| </row> |
| <row> |
| <entry><literal>can_exclude</literal></entry> |
| <entry>Does the access method support exclusion constraints? |
| </entry> |
| </row> |
| <row> |
| <entry><literal>can_include</literal></entry> |
| <entry>Does the access method support the <literal>INCLUDE</literal> |
| clause of <literal>CREATE INDEX</literal>? |
| </entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| <xref linkend="functions-info-object-table"/> lists functions related to |
| database object identification and addressing. |
| </para> |
| |
| <table id="functions-info-object-table"> |
| <title>Object Information and Addressing Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_describe_object</primary> |
| </indexterm> |
| <function>pg_describe_object</function> ( <parameter>classid</parameter> <type>oid</type>, <parameter>objid</parameter> <type>oid</type>, <parameter>objsubid</parameter> <type>integer</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Returns a textual description of a database object identified by |
| catalog OID, object OID, and sub-object ID (such as a column number |
| within a table; the sub-object ID is zero when referring to a whole |
| object). This description is intended to be human-readable, and might |
| be translated, depending on server configuration. This is especially |
| useful to determine the identity of an object referenced in the |
| <structname>pg_depend</structname> catalog. This function returns |
| <literal>NULL</literal> values for undefined objects. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_identify_object</primary> |
| </indexterm> |
| <function>pg_identify_object</function> ( <parameter>classid</parameter> <type>oid</type>, <parameter>objid</parameter> <type>oid</type>, <parameter>objsubid</parameter> <type>integer</type> ) |
| <returnvalue>record</returnvalue> |
| ( <parameter>type</parameter> <type>text</type>, |
| <parameter>schema</parameter> <type>text</type>, |
| <parameter>name</parameter> <type>text</type>, |
| <parameter>identity</parameter> <type>text</type> ) |
| </para> |
| <para> |
| Returns a row containing enough information to uniquely identify the |
| database object specified by catalog OID, object OID and sub-object |
| ID. |
| This information is intended to be machine-readable, and is never |
| translated. |
| <parameter>type</parameter> identifies the type of database object; |
| <parameter>schema</parameter> is the schema name that the object |
| belongs in, or <literal>NULL</literal> for object types that do not |
| belong to schemas; |
| <parameter>name</parameter> is the name of the object, quoted if |
| necessary, if the name (along with schema name, if pertinent) is |
| sufficient to uniquely identify the object, |
| otherwise <literal>NULL</literal>; |
| <parameter>identity</parameter> is the complete object identity, with |
| the precise format depending on object type, and each name within the |
| format being schema-qualified and quoted as necessary. Undefined |
| objects are identified with <literal>NULL</literal> values. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_identify_object_as_address</primary> |
| </indexterm> |
| <function>pg_identify_object_as_address</function> ( <parameter>classid</parameter> <type>oid</type>, <parameter>objid</parameter> <type>oid</type>, <parameter>objsubid</parameter> <type>integer</type> ) |
| <returnvalue>record</returnvalue> |
| ( <parameter>type</parameter> <type>text</type>, |
| <parameter>object_names</parameter> <type>text[]</type>, |
| <parameter>object_args</parameter> <type>text[]</type> ) |
| </para> |
| <para> |
| Returns a row containing enough information to uniquely identify the |
| database object specified by catalog OID, object OID and sub-object |
| ID. |
| The returned information is independent of the current server, that |
| is, it could be used to identify an identically named object in |
| another server. |
| <parameter>type</parameter> identifies the type of database object; |
| <parameter>object_names</parameter> and |
| <parameter>object_args</parameter> |
| are text arrays that together form a reference to the object. |
| These three values can be passed |
| to <function>pg_get_object_address</function> to obtain the internal |
| address of the object. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_get_object_address</primary> |
| </indexterm> |
| <function>pg_get_object_address</function> ( <parameter>type</parameter> <type>text</type>, <parameter>object_names</parameter> <type>text[]</type>, <parameter>object_args</parameter> <type>text[]</type> ) |
| <returnvalue>record</returnvalue> |
| ( <parameter>classid</parameter> <type>oid</type>, |
| <parameter>objid</parameter> <type>oid</type>, |
| <parameter>objsubid</parameter> <type>integer</type> ) |
| </para> |
| <para> |
| Returns a row containing enough information to uniquely identify the |
| database object specified by a type code and object name and argument |
| arrays. |
| The returned values are the ones that would be used in system catalogs |
| such as <structname>pg_depend</structname>; they can be passed to |
| other system functions such as <function>pg_describe_object</function> |
| or <function>pg_identify_object</function>. |
| <parameter>classid</parameter> is the OID of the system catalog |
| containing the object; |
| <parameter>objid</parameter> is the OID of the object itself, and |
| <parameter>objsubid</parameter> is the sub-object ID, or zero if none. |
| This function is the inverse |
| of <function>pg_identify_object_as_address</function>. |
| Undefined objects are identified with <literal>NULL</literal> values. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <indexterm> |
| <primary>comment</primary> |
| <secondary sortas="database objects">about database objects</secondary> |
| </indexterm> |
| |
| <para> |
| The functions shown in <xref linkend="functions-info-comment-table"/> |
| extract comments previously stored with the <xref linkend="sql-comment"/> |
| command. A null value is returned if no |
| comment could be found for the specified parameters. |
| </para> |
| |
| <table id="functions-info-comment-table"> |
| <title>Comment Information Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>col_description</primary> |
| </indexterm> |
| <function>col_description</function> ( <parameter>table</parameter> <type>oid</type>, <parameter>column</parameter> <type>integer</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Returns the comment for a table column, which is specified by the OID |
| of its table and its column number. |
| (<function>obj_description</function> cannot be used for table |
| columns, since columns do not have OIDs of their own.) |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>obj_description</primary> |
| </indexterm> |
| <function>obj_description</function> ( <parameter>object</parameter> <type>oid</type>, <parameter>catalog</parameter> <type>name</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Returns the comment for a database object specified by its OID and the |
| name of the containing system catalog. For |
| example, <literal>obj_description(123456, 'pg_class')</literal> would |
| retrieve the comment for the table with OID 123456. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>obj_description</function> ( <parameter>object</parameter> <type>oid</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Returns the comment for a database object specified by its OID alone. |
| This is <emphasis>deprecated</emphasis> since there is no guarantee |
| that OIDs are unique across different system catalogs; therefore, the |
| wrong comment might be returned. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>shobj_description</primary> |
| </indexterm> |
| <function>shobj_description</function> ( <parameter>object</parameter> <type>oid</type>, <parameter>catalog</parameter> <type>name</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Returns the comment for a shared database object specified by its OID |
| and the name of the containing system catalog. This is just |
| like <function>obj_description</function> except that it is used for |
| retrieving comments on shared objects (that is, databases, roles, and |
| tablespaces). Some system catalogs are global to all databases within |
| each cluster, and the descriptions for objects in them are stored |
| globally as well. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| The functions shown in <xref linkend="functions-pg-snapshot"/> |
| provide server transaction information in an exportable form. The main |
| use of these functions is to determine which transactions were committed |
| between two snapshots. |
| </para> |
| |
| <table id="functions-pg-snapshot"> |
| <title>Transaction ID and Snapshot Information Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_current_xact_id</primary> |
| </indexterm> |
| <function>pg_current_xact_id</function> () |
| <returnvalue>xid8</returnvalue> |
| </para> |
| <para> |
| Returns the current transaction's ID. It will assign a new one if the |
| current transaction does not have one already (because it has not |
| performed any database updates). |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_current_xact_id_if_assigned</primary> |
| </indexterm> |
| <function>pg_current_xact_id_if_assigned</function> () |
| <returnvalue>xid8</returnvalue> |
| </para> |
| <para> |
| Returns the current transaction's ID, or <literal>NULL</literal> if no |
| ID is assigned yet. (It's best to use this variant if the transaction |
| might otherwise be read-only, to avoid unnecessary consumption of an |
| XID.) |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_xact_status</primary> |
| </indexterm> |
| <function>pg_xact_status</function> ( <type>xid8</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Reports the commit status of a recent transaction. |
| The result is one of <literal>in progress</literal>, |
| <literal>committed</literal>, or <literal>aborted</literal>, |
| provided that the transaction is recent enough that the system retains |
| the commit status of that transaction. |
| If it is old enough that no references to the transaction survive in |
| the system and the commit status information has been discarded, the |
| result is <literal>NULL</literal>. |
| Applications might use this function, for example, to determine |
| whether their transaction committed or aborted after the application |
| and database server become disconnected while |
| a <literal>COMMIT</literal> is in progress. |
| Note that prepared transactions are reported as <literal>in |
| progress</literal>; applications must check <link |
| linkend="view-pg-prepared-xacts"><structname>pg_prepared_xacts</structname></link> |
| if they need to determine whether a transaction ID belongs to a |
| prepared transaction. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_current_snapshot</primary> |
| </indexterm> |
| <function>pg_current_snapshot</function> () |
| <returnvalue>pg_snapshot</returnvalue> |
| </para> |
| <para> |
| Returns a current <firstterm>snapshot</firstterm>, a data structure |
| showing which transaction IDs are now in-progress. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_snapshot_xip</primary> |
| </indexterm> |
| <function>pg_snapshot_xip</function> ( <type>pg_snapshot</type> ) |
| <returnvalue>setof xid8</returnvalue> |
| </para> |
| <para> |
| Returns the set of in-progress transaction IDs contained in a snapshot. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_snapshot_xmax</primary> |
| </indexterm> |
| <function>pg_snapshot_xmax</function> ( <type>pg_snapshot</type> ) |
| <returnvalue>xid8</returnvalue> |
| </para> |
| <para> |
| Returns the <structfield>xmax</structfield> of a snapshot. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_snapshot_xmin</primary> |
| </indexterm> |
| <function>pg_snapshot_xmin</function> ( <type>pg_snapshot</type> ) |
| <returnvalue>xid8</returnvalue> |
| </para> |
| <para> |
| Returns the <structfield>xmin</structfield> of a snapshot. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_visible_in_snapshot</primary> |
| </indexterm> |
| <function>pg_visible_in_snapshot</function> ( <type>xid8</type>, <type>pg_snapshot</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Is the given transaction ID <firstterm>visible</firstterm> according |
| to this snapshot (that is, was it completed before the snapshot was |
| taken)? Note that this function will not give the correct answer for |
| a subtransaction ID. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| The internal transaction ID type <type>xid</type> is 32 bits wide and |
| wraps around every 4 billion transactions. However, |
| the functions shown in <xref linkend="functions-pg-snapshot"/> use a |
| 64-bit type <type>xid8</type> that does not wrap around during the life |
| of an installation, and can be converted to <type>xid</type> by casting if |
| required. The data type <type>pg_snapshot</type> stores information about |
| transaction ID visibility at a particular moment in time. Its components |
| are described in <xref linkend="functions-pg-snapshot-parts"/>. |
| <type>pg_snapshot</type>'s textual representation is |
| <literal><replaceable>xmin</replaceable>:<replaceable>xmax</replaceable>:<replaceable>xip_list</replaceable></literal>. |
| For example <literal>10:20:10,14,15</literal> means |
| <literal>xmin=10, xmax=20, xip_list=10, 14, 15</literal>. |
| </para> |
| |
| <table id="functions-pg-snapshot-parts"> |
| <title>Snapshot Components</title> |
| <tgroup cols="2"> |
| <thead> |
| <row> |
| <entry>Name</entry> |
| <entry>Description</entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry><structfield>xmin</structfield></entry> |
| <entry> |
| Lowest transaction ID that was still active. All transaction IDs |
| less than <structfield>xmin</structfield> are either committed and visible, |
| or rolled back and dead. |
| </entry> |
| </row> |
| |
| <row> |
| <entry><structfield>xmax</structfield></entry> |
| <entry> |
| One past the highest completed transaction ID. All transaction IDs |
| greater than or equal to <structfield>xmax</structfield> had not yet |
| completed as of the time of the snapshot, and thus are invisible. |
| </entry> |
| </row> |
| |
| <row> |
| <entry><structfield>xip_list</structfield></entry> |
| <entry> |
| Transactions in progress at the time of the snapshot. A transaction |
| ID that is <literal>xmin <= <replaceable>X</replaceable> < |
| xmax</literal> and not in this list was already completed at the time |
| of the snapshot, and thus is either visible or dead according to its |
| commit status. This list does not include the transaction IDs of |
| subtransactions. |
| </entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| In releases of <productname>PostgreSQL</productname> before 13 there was |
| no <type>xid8</type> type, so variants of these functions were provided |
| that used <type>bigint</type> to represent a 64-bit XID, with a |
| correspondingly distinct snapshot data type <type>txid_snapshot</type>. |
| These older functions have <literal>txid</literal> in their names. They |
| are still supported for backward compatibility, but may be removed from a |
| future release. See <xref linkend="functions-txid-snapshot"/>. |
| </para> |
| |
| <table id="functions-txid-snapshot"> |
| <title>Deprecated Transaction ID and Snapshot Information Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>txid_current</primary> |
| </indexterm> |
| <function>txid_current</function> () |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para> |
| See <function>pg_current_xact_id()</function>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>txid_current_if_assigned</primary> |
| </indexterm> |
| <function>txid_current_if_assigned</function> () |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para> |
| See <function>pg_current_xact_id_if_assigned()</function>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>txid_current_snapshot</primary> |
| </indexterm> |
| <function>txid_current_snapshot</function> () |
| <returnvalue>txid_snapshot</returnvalue> |
| </para> |
| <para> |
| See <function>pg_current_snapshot()</function>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>txid_snapshot_xip</primary> |
| </indexterm> |
| <function>txid_snapshot_xip</function> ( <type>txid_snapshot</type> ) |
| <returnvalue>setof bigint</returnvalue> |
| </para> |
| <para> |
| See <function>pg_snapshot_xip()</function>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>txid_snapshot_xmax</primary> |
| </indexterm> |
| <function>txid_snapshot_xmax</function> ( <type>txid_snapshot</type> ) |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para> |
| See <function>pg_snapshot_xmax()</function>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>txid_snapshot_xmin</primary> |
| </indexterm> |
| <function>txid_snapshot_xmin</function> ( <type>txid_snapshot</type> ) |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para> |
| See <function>pg_snapshot_xmin()</function>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>txid_visible_in_snapshot</primary> |
| </indexterm> |
| <function>txid_visible_in_snapshot</function> ( <type>bigint</type>, <type>txid_snapshot</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| See <function>pg_visible_in_snapshot()</function>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>txid_status</primary> |
| </indexterm> |
| <function>txid_status</function> ( <type>bigint</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| See <function>pg_xact_status()</function>. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| The functions shown in <xref linkend="functions-commit-timestamp"/> |
| provide information about when past transactions were committed. |
| They only provide useful data when the |
| <xref linkend="guc-track-commit-timestamp"/> configuration option is |
| enabled, and only for transactions that were committed after it was |
| enabled. |
| </para> |
| |
| <table id="functions-commit-timestamp"> |
| <title>Committed Transaction Information Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_xact_commit_timestamp</primary> |
| </indexterm> |
| <function>pg_xact_commit_timestamp</function> ( <type>xid</type> ) |
| <returnvalue>timestamp with time zone</returnvalue> |
| </para> |
| <para> |
| Returns the commit timestamp of a transaction. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_xact_commit_timestamp_origin</primary> |
| </indexterm> |
| <function>pg_xact_commit_timestamp_origin</function> ( <type>xid</type> ) |
| <returnvalue>record</returnvalue> |
| ( <parameter>timestamp</parameter> <type>timestamp with time zone</type>, |
| <parameter>roident</parameter> <type>oid</type>) |
| </para> |
| <para> |
| Returns the commit timestamp and replication origin of a transaction. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_last_committed_xact</primary> |
| </indexterm> |
| <function>pg_last_committed_xact</function> () |
| <returnvalue>record</returnvalue> |
| ( <parameter>xid</parameter> <type>xid</type>, |
| <parameter>timestamp</parameter> <type>timestamp with time zone</type>, |
| <parameter>roident</parameter> <type>oid</type> ) |
| </para> |
| <para> |
| Returns the transaction ID, commit timestamp and replication origin |
| of the latest committed transaction. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| The functions shown in <xref linkend="functions-controldata"/> |
| print information initialized during <command>initdb</command>, such |
| as the catalog version. They also show information about write-ahead |
| logging and checkpoint processing. This information is cluster-wide, |
| not specific to any one database. These functions provide most of the same |
| information, from the same source, as the |
| <xref linkend="app-pgcontroldata"/> application. |
| </para> |
| |
| <table id="functions-controldata"> |
| <title>Control Data Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_control_checkpoint</primary> |
| </indexterm> |
| <function>pg_control_checkpoint</function> () |
| <returnvalue>record</returnvalue> |
| </para> |
| <para> |
| Returns information about current checkpoint state, as shown in |
| <xref linkend="functions-pg-control-checkpoint"/>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_control_system</primary> |
| </indexterm> |
| <function>pg_control_system</function> () |
| <returnvalue>record</returnvalue> |
| </para> |
| <para> |
| Returns information about current control file state, as shown in |
| <xref linkend="functions-pg-control-system"/>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_control_init</primary> |
| </indexterm> |
| <function>pg_control_init</function> () |
| <returnvalue>record</returnvalue> |
| </para> |
| <para> |
| Returns information about cluster initialization state, as shown in |
| <xref linkend="functions-pg-control-init"/>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_control_recovery</primary> |
| </indexterm> |
| <function>pg_control_recovery</function> () |
| <returnvalue>record</returnvalue> |
| </para> |
| <para> |
| Returns information about recovery state, as shown in |
| <xref linkend="functions-pg-control-recovery"/>. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <table id="functions-pg-control-checkpoint"> |
| <title><function>pg_control_checkpoint</function> Output Columns</title> |
| <tgroup cols="2"> |
| <thead> |
| <row> |
| <entry>Column Name</entry> |
| <entry>Data Type</entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| |
| <row> |
| <entry><structfield>checkpoint_lsn</structfield></entry> |
| <entry><type>pg_lsn</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>redo_lsn</structfield></entry> |
| <entry><type>pg_lsn</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>redo_wal_file</structfield></entry> |
| <entry><type>text</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>timeline_id</structfield></entry> |
| <entry><type>integer</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>prev_timeline_id</structfield></entry> |
| <entry><type>integer</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>full_page_writes</structfield></entry> |
| <entry><type>boolean</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>next_xid</structfield></entry> |
| <entry><type>text</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>next_oid</structfield></entry> |
| <entry><type>oid</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>next_multixact_id</structfield></entry> |
| <entry><type>xid</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>next_multi_offset</structfield></entry> |
| <entry><type>xid</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>oldest_xid</structfield></entry> |
| <entry><type>xid</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>oldest_xid_dbid</structfield></entry> |
| <entry><type>oid</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>oldest_active_xid</structfield></entry> |
| <entry><type>xid</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>oldest_multi_xid</structfield></entry> |
| <entry><type>xid</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>oldest_multi_dbid</structfield></entry> |
| <entry><type>oid</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>oldest_commit_ts_xid</structfield></entry> |
| <entry><type>xid</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>newest_commit_ts_xid</structfield></entry> |
| <entry><type>xid</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>checkpoint_time</structfield></entry> |
| <entry><type>timestamp with time zone</type></entry> |
| </row> |
| |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <table id="functions-pg-control-system"> |
| <title><function>pg_control_system</function> Output Columns</title> |
| <tgroup cols="2"> |
| <thead> |
| <row> |
| <entry>Column Name</entry> |
| <entry>Data Type</entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| |
| <row> |
| <entry><structfield>pg_control_version</structfield></entry> |
| <entry><type>integer</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>catalog_version_no</structfield></entry> |
| <entry><type>integer</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>system_identifier</structfield></entry> |
| <entry><type>bigint</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>pg_control_last_modified</structfield></entry> |
| <entry><type>timestamp with time zone</type></entry> |
| </row> |
| |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <table id="functions-pg-control-init"> |
| <title><function>pg_control_init</function> Output Columns</title> |
| <tgroup cols="2"> |
| <thead> |
| <row> |
| <entry>Column Name</entry> |
| <entry>Data Type</entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| |
| <row> |
| <entry><structfield>max_data_alignment</structfield></entry> |
| <entry><type>integer</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>database_block_size</structfield></entry> |
| <entry><type>integer</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>blocks_per_segment</structfield></entry> |
| <entry><type>integer</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>wal_block_size</structfield></entry> |
| <entry><type>integer</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>bytes_per_wal_segment</structfield></entry> |
| <entry><type>integer</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>max_identifier_length</structfield></entry> |
| <entry><type>integer</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>max_index_columns</structfield></entry> |
| <entry><type>integer</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>max_toast_chunk_size</structfield></entry> |
| <entry><type>integer</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>large_object_chunk_size</structfield></entry> |
| <entry><type>integer</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>float8_pass_by_value</structfield></entry> |
| <entry><type>boolean</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>data_page_checksum_version</structfield></entry> |
| <entry><type>integer</type></entry> |
| </row> |
| |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <table id="functions-pg-control-recovery"> |
| <title><function>pg_control_recovery</function> Output Columns</title> |
| <tgroup cols="2"> |
| <thead> |
| <row> |
| <entry>Column Name</entry> |
| <entry>Data Type</entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| |
| <row> |
| <entry><structfield>min_recovery_end_lsn</structfield></entry> |
| <entry><type>pg_lsn</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>min_recovery_end_timeline</structfield></entry> |
| <entry><type>integer</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>backup_start_lsn</structfield></entry> |
| <entry><type>pg_lsn</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>backup_end_lsn</structfield></entry> |
| <entry><type>pg_lsn</type></entry> |
| </row> |
| |
| <row> |
| <entry><structfield>end_of_backup_record_required</structfield></entry> |
| <entry><type>boolean</type></entry> |
| </row> |
| |
| </tbody> |
| </tgroup> |
| </table> |
| |
| </sect1> |
| |
| <sect1 id="functions-admin"> |
| <title>System Administration Functions</title> |
| |
| <para> |
| The functions described in this section are used to control and |
| monitor a <productname>PostgreSQL</productname> installation. |
| </para> |
| |
| <sect2 id="functions-admin-set"> |
| <title>Configuration Settings Functions</title> |
| |
| <indexterm> |
| <primary>SET</primary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>SHOW</primary> |
| </indexterm> |
| |
| <indexterm> |
| <primary>configuration</primary> |
| <secondary sortas="server">of the server</secondary> |
| <tertiary>functions</tertiary> |
| </indexterm> |
| |
| <para> |
| <xref linkend="functions-admin-set-table"/> shows the functions |
| available to query and alter run-time configuration parameters. |
| </para> |
| |
| <table id="functions-admin-set-table"> |
| <title>Configuration Settings Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example(s) |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>current_setting</primary> |
| </indexterm> |
| <function>current_setting</function> ( <parameter>setting_name</parameter> <type>text</type> <optional>, <parameter>missing_ok</parameter> <type>boolean</type> </optional> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Returns the current value of the |
| setting <parameter>setting_name</parameter>. If there is no such |
| setting, <function>current_setting</function> throws an error |
| unless <parameter>missing_ok</parameter> is supplied and |
| is <literal>true</literal> (in which case NULL is returned). |
| This function corresponds to |
| the <acronym>SQL</acronym> command <xref linkend="sql-show"/>. |
| </para> |
| <para> |
| <literal>current_setting('datestyle')</literal> |
| <returnvalue>ISO, MDY</returnvalue> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>set_config</primary> |
| </indexterm> |
| <function>set_config</function> ( |
| <parameter>setting_name</parameter> <type>text</type>, |
| <parameter>new_value</parameter> <type>text</type>, |
| <parameter>is_local</parameter> <type>boolean</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Sets the parameter <parameter>setting_name</parameter> |
| to <parameter>new_value</parameter>, and returns that value. |
| If <parameter>is_local</parameter> is <literal>true</literal>, the new |
| value will only apply during the current transaction. If you want the |
| new value to apply for the rest of the current session, |
| use <literal>false</literal> instead. This function corresponds to |
| the SQL command <xref linkend="sql-set"/>. |
| </para> |
| <para> |
| <literal>set_config('log_statement_stats', 'off', false)</literal> |
| <returnvalue>off</returnvalue> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| </sect2> |
| |
| <sect2 id="functions-admin-signal"> |
| <title>Server Signaling Functions</title> |
| |
| <indexterm> |
| <primary>signal</primary> |
| <secondary sortas="backend">backend processes</secondary> |
| </indexterm> |
| |
| <para> |
| The functions shown in <xref |
| linkend="functions-admin-signal-table"/> send control signals to |
| other server processes. Use of these functions is restricted to |
| superusers by default but access may be granted to others using |
| <command>GRANT</command>, with noted exceptions. |
| </para> |
| |
| <para> |
| Each of these functions returns <literal>true</literal> if |
| the signal was successfully sent and <literal>false</literal> |
| if sending the signal failed. |
| </para> |
| |
| <table id="functions-admin-signal-table"> |
| <title>Server Signaling Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_cancel_backend</primary> |
| </indexterm> |
| <function>pg_cancel_backend</function> ( <parameter>pid</parameter> <type>integer</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Cancels the current query of the session whose backend process has the |
| specified process ID. This is also allowed if the |
| calling role is a member of the role whose backend is being canceled or |
| the calling role has been granted <literal>pg_signal_backend</literal>, |
| however only superusers can cancel superuser backends. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_log_backend_memory_contexts</primary> |
| </indexterm> |
| <function>pg_log_backend_memory_contexts</function> ( <parameter>pid</parameter> <type>integer</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Requests to log the memory contexts of the backend with the |
| specified process ID. These memory contexts will be logged at |
| <literal>LOG</literal> message level. They will appear in |
| the server log based on the log configuration set |
| (See <xref linkend="runtime-config-logging"/> for more information), |
| but will not be sent to the client regardless of |
| <xref linkend="guc-client-min-messages"/>. |
| Only superusers can request to log the memory contexts. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_reload_conf</primary> |
| </indexterm> |
| <function>pg_reload_conf</function> () |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Causes all processes of the <productname>PostgreSQL</productname> |
| server to reload their configuration files. (This is initiated by |
| sending a <systemitem>SIGHUP</systemitem> signal to the postmaster |
| process, which in turn sends <systemitem>SIGHUP</systemitem> to each |
| of its children.) You can use the |
| <link linkend="view-pg-file-settings"><structname>pg_file_settings</structname></link> and |
| <link linkend="view-pg-hba-file-rules"><structname>pg_hba_file_rules</structname></link> views |
| to check the configuration files for possible errors, before reloading. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_rotate_logfile</primary> |
| </indexterm> |
| <function>pg_rotate_logfile</function> () |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Signals the log-file manager to switch to a new output file |
| immediately. This works only when the built-in log collector is |
| running, since otherwise there is no log-file manager subprocess. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_terminate_backend</primary> |
| </indexterm> |
| <function>pg_terminate_backend</function> ( <parameter>pid</parameter> <type>integer</type>, <parameter>timeout</parameter> <type>bigint</type> <literal>DEFAULT</literal> <literal>0</literal> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Terminates the session whose backend process has the |
| specified process ID. This is also allowed if the calling role |
| is a member of the role whose backend is being terminated or the |
| calling role has been granted <literal>pg_signal_backend</literal>, |
| however only superusers can terminate superuser backends. |
| </para> |
| <para> |
| If <parameter>timeout</parameter> is not specified or zero, this |
| function returns <literal>true</literal> whether the process actually |
| terminates or not, indicating only that the sending of the signal was |
| successful. If the <parameter>timeout</parameter> is specified (in |
| milliseconds) and greater than zero, the function waits until the |
| process is actually terminated or until the given time has passed. If |
| the process is terminated, the function |
| returns <literal>true</literal>. On timeout, a warning is emitted and |
| <literal>false</literal> is returned. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| <function>pg_cancel_backend</function> and <function>pg_terminate_backend</function> |
| send signals (<systemitem>SIGINT</systemitem> or <systemitem>SIGTERM</systemitem> |
| respectively) to backend processes identified by process ID. |
| The process ID of an active backend can be found from |
| the <structfield>pid</structfield> column of the |
| <structname>pg_stat_activity</structname> view, or by listing the |
| <command>postgres</command> processes on the server (using |
| <application>ps</application> on Unix or the <application>Task |
| Manager</application> on <productname>Windows</productname>). |
| The role of an active backend can be found from the |
| <structfield>usename</structfield> column of the |
| <structname>pg_stat_activity</structname> view. |
| </para> |
| |
| <para> |
| <function>pg_log_backend_memory_contexts</function> can be used |
| to log the memory contexts of a backend process. For example: |
| <programlisting> |
| postgres=# SELECT pg_log_backend_memory_contexts(pg_backend_pid()); |
| pg_log_backend_memory_contexts |
| -------------------------------- |
| t |
| (1 row) |
| </programlisting> |
| One message for each memory context will be logged. For example: |
| <screen> |
| LOG: logging memory contexts of PID 10377 |
| STATEMENT: SELECT pg_log_backend_memory_contexts(pg_backend_pid()); |
| LOG: level: 0; TopMemoryContext: 80800 total in 6 blocks; 14432 free (5 chunks); 66368 used |
| LOG: level: 1; pgstat TabStatusArray lookup hash table: 8192 total in 1 blocks; 1408 free (0 chunks); 6784 used |
| LOG: level: 1; TopTransactionContext: 8192 total in 1 blocks; 7720 free (1 chunks); 472 used |
| LOG: level: 1; RowDescriptionContext: 8192 total in 1 blocks; 6880 free (0 chunks); 1312 used |
| LOG: level: 1; MessageContext: 16384 total in 2 blocks; 5152 free (0 chunks); 11232 used |
| LOG: level: 1; Operator class cache: 8192 total in 1 blocks; 512 free (0 chunks); 7680 used |
| LOG: level: 1; smgr relation table: 16384 total in 2 blocks; 4544 free (3 chunks); 11840 used |
| LOG: level: 1; TransactionAbortContext: 32768 total in 1 blocks; 32504 free (0 chunks); 264 used |
| ... |
| LOG: level: 1; ErrorContext: 8192 total in 1 blocks; 7928 free (3 chunks); 264 used |
| LOG: Grand total: 1651920 bytes in 201 blocks; 622360 free (88 chunks); 1029560 used |
| </screen> |
| If there are more than 100 child contexts under the same parent, the first |
| 100 child contexts are logged, along with a summary of the remaining contexts. |
| Note that frequent calls to this function could incur significant overhead, |
| because it may generate a large number of log messages. |
| </para> |
| |
| </sect2> |
| |
| <sect2 id="functions-admin-backup"> |
| <title>Backup Control Functions</title> |
| |
| <indexterm> |
| <primary>backup</primary> |
| </indexterm> |
| |
| <para> |
| The functions shown in <xref |
| linkend="functions-admin-backup-table"/> assist in making on-line backups. |
| These functions cannot be executed during recovery (except |
| non-exclusive <function>pg_start_backup</function>, |
| non-exclusive <function>pg_stop_backup</function>, |
| <function>pg_is_in_backup</function>, <function>pg_backup_start_time</function> |
| and <function>pg_wal_lsn_diff</function>). |
| </para> |
| |
| <para> |
| For details about proper usage of these functions, see |
| <xref linkend="continuous-archiving"/>. |
| </para> |
| |
| <table id="functions-admin-backup-table"> |
| <title>Backup Control Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_create_restore_point</primary> |
| </indexterm> |
| <function>pg_create_restore_point</function> ( <parameter>name</parameter> <type>text</type> ) |
| <returnvalue>pg_lsn</returnvalue> |
| </para> |
| <para> |
| Creates a named marker record in the write-ahead log that can later be |
| used as a recovery target, and returns the corresponding write-ahead |
| log location. The given name can then be used with |
| <xref linkend="guc-recovery-target-name"/> to specify the point up to |
| which recovery will proceed. Avoid creating multiple restore points |
| with the same name, since recovery will stop at the first one whose |
| name matches the recovery target. |
| </para> |
| <para> |
| This function is restricted to superusers by default, but other users |
| can be granted EXECUTE to run the function. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_current_wal_flush_lsn</primary> |
| </indexterm> |
| <function>pg_current_wal_flush_lsn</function> () |
| <returnvalue>pg_lsn</returnvalue> |
| </para> |
| <para> |
| Returns the current write-ahead log flush location (see notes below). |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_current_wal_insert_lsn</primary> |
| </indexterm> |
| <function>pg_current_wal_insert_lsn</function> () |
| <returnvalue>pg_lsn</returnvalue> |
| </para> |
| <para> |
| Returns the current write-ahead log insert location (see notes below). |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_current_wal_lsn</primary> |
| </indexterm> |
| <function>pg_current_wal_lsn</function> () |
| <returnvalue>pg_lsn</returnvalue> |
| </para> |
| <para> |
| Returns the current write-ahead log write location (see notes below). |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_start_backup</primary> |
| </indexterm> |
| <function>pg_start_backup</function> ( |
| <parameter>label</parameter> <type>text</type> |
| <optional>, <parameter>fast</parameter> <type>boolean</type> |
| <optional>, <parameter>exclusive</parameter> <type>boolean</type> |
| </optional></optional> ) |
| <returnvalue>pg_lsn</returnvalue> |
| </para> |
| <para> |
| Prepares the server to begin an on-line backup. The only required |
| parameter is an arbitrary user-defined label for the backup. |
| (Typically this would be the name under which the backup dump file |
| will be stored.) |
| If the optional second parameter is given as <literal>true</literal>, |
| it specifies executing <function>pg_start_backup</function> as quickly |
| as possible. This forces an immediate checkpoint which will cause a |
| spike in I/O operations, slowing any concurrently executing queries. |
| The optional third parameter specifies whether to perform an exclusive |
| or non-exclusive backup (default is exclusive). |
| </para> |
| <para> |
| When used in exclusive mode, this function writes a backup label file |
| (<filename>backup_label</filename>) and, if there are any links in |
| the <filename>pg_tblspc/</filename> directory, a tablespace map file |
| (<filename>tablespace_map</filename>) into the database cluster's data |
| directory, then performs a checkpoint, and then returns the backup's |
| starting write-ahead log location. (The user can ignore this |
| result value, but it is provided in case it is useful.) When used in |
| non-exclusive mode, the contents of these files are instead returned |
| by the <function>pg_stop_backup</function> function, and should be |
| copied to the backup area by the user. |
| </para> |
| <para> |
| This function is restricted to superusers by default, but other users |
| can be granted EXECUTE to run the function. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_stop_backup</primary> |
| </indexterm> |
| <function>pg_stop_backup</function> ( |
| <parameter>exclusive</parameter> <type>boolean</type> |
| <optional>, <parameter>wait_for_archive</parameter> <type>boolean</type> |
| </optional> ) |
| <returnvalue>setof record</returnvalue> |
| ( <parameter>lsn</parameter> <type>pg_lsn</type>, |
| <parameter>labelfile</parameter> <type>text</type>, |
| <parameter>spcmapfile</parameter> <type>text</type> ) |
| </para> |
| <para> |
| Finishes performing an exclusive or non-exclusive on-line backup. |
| The <parameter>exclusive</parameter> parameter must match the |
| previous <function>pg_start_backup</function> call. |
| In an exclusive backup, <function>pg_stop_backup</function> removes |
| the backup label file and, if it exists, the tablespace map file |
| created by <function>pg_start_backup</function>. In a non-exclusive |
| backup, the desired contents of these files are returned as part of |
| the result of the function, and should be written to files in the |
| backup area (not in the data directory). |
| </para> |
| <para> |
| There is an optional second parameter of type <type>boolean</type>. |
| If false, the function will return immediately after the backup is |
| completed, without waiting for WAL to be archived. This behavior is |
| only useful with backup software that independently monitors WAL |
| archiving. Otherwise, WAL required to make the backup consistent might |
| be missing and make the backup useless. By default or when this |
| parameter is true, <function>pg_stop_backup</function> will wait for |
| WAL to be archived when archiving is enabled. (On a standby, this |
| means that it will wait only when <varname>archive_mode</varname> = |
| <literal>always</literal>. If write activity on the primary is low, |
| it may be useful to run <function>pg_switch_wal</function> on the |
| primary in order to trigger an immediate segment switch.) |
| </para> |
| <para> |
| When executed on a primary, this function also creates a backup |
| history file in the write-ahead log archive area. The history file |
| includes the label given to <function>pg_start_backup</function>, the |
| starting and ending write-ahead log locations for the backup, and the |
| starting and ending times of the backup. After recording the ending |
| location, the current write-ahead log insertion point is automatically |
| advanced to the next write-ahead log file, so that the ending |
| write-ahead log file can be archived immediately to complete the |
| backup. |
| </para> |
| <para> |
| The result of the function is a single record. |
| The <parameter>lsn</parameter> column holds the backup's ending |
| write-ahead log location (which again can be ignored). The second and |
| third columns are <literal>NULL</literal> when ending an exclusive |
| backup; after a non-exclusive backup they hold the desired contents of |
| the label and tablespace map files. |
| </para> |
| <para> |
| This function is restricted to superusers by default, but other users |
| can be granted EXECUTE to run the function. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <function>pg_stop_backup</function> () |
| <returnvalue>pg_lsn</returnvalue> |
| </para> |
| <para> |
| Finishes performing an exclusive on-line backup. This simplified |
| version is equivalent to <literal>pg_stop_backup(true, |
| true)</literal>, except that it only returns the <type>pg_lsn</type> |
| result. |
| </para> |
| <para> |
| This function is restricted to superusers by default, but other users |
| can be granted EXECUTE to run the function. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_is_in_backup</primary> |
| </indexterm> |
| <function>pg_is_in_backup</function> () |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Returns true if an on-line exclusive backup is in progress. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_backup_start_time</primary> |
| </indexterm> |
| <function>pg_backup_start_time</function> () |
| <returnvalue>timestamp with time zone</returnvalue> |
| </para> |
| <para> |
| Returns the start time of the current on-line exclusive backup if one |
| is in progress, otherwise <literal>NULL</literal>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_switch_wal</primary> |
| </indexterm> |
| <function>pg_switch_wal</function> () |
| <returnvalue>pg_lsn</returnvalue> |
| </para> |
| <para> |
| Forces the server to switch to a new write-ahead log file, which |
| allows the current file to be archived (assuming you are using |
| continuous archiving). The result is the ending write-ahead log |
| location plus 1 within the just-completed write-ahead log file. If |
| there has been no write-ahead log activity since the last write-ahead |
| log switch, <function>pg_switch_wal</function> does nothing and |
| returns the start location of the write-ahead log file currently in |
| use. |
| </para> |
| <para> |
| This function is restricted to superusers by default, but other users |
| can be granted EXECUTE to run the function. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_walfile_name</primary> |
| </indexterm> |
| <function>pg_walfile_name</function> ( <parameter>lsn</parameter> <type>pg_lsn</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Converts a write-ahead log location to the name of the WAL file |
| holding that location. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_walfile_name_offset</primary> |
| </indexterm> |
| <function>pg_walfile_name_offset</function> ( <parameter>lsn</parameter> <type>pg_lsn</type> ) |
| <returnvalue>record</returnvalue> |
| ( <parameter>file_name</parameter> <type>text</type>, |
| <parameter>file_offset</parameter> <type>integer</type> ) |
| </para> |
| <para> |
| Converts a write-ahead log location to a WAL file name and byte offset |
| within that file. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_wal_lsn_diff</primary> |
| </indexterm> |
| <function>pg_wal_lsn_diff</function> ( <parameter>lsn1</parameter> <type>pg_lsn</type>, <parameter>lsn2</parameter> <type>pg_lsn</type> ) |
| <returnvalue>numeric</returnvalue> |
| </para> |
| <para> |
| Calculates the difference in bytes (<parameter>lsn1</parameter> - <parameter>lsn2</parameter>) between two write-ahead log |
| locations. This can be used |
| with <structname>pg_stat_replication</structname> or some of the |
| functions shown in <xref linkend="functions-admin-backup-table"/> to |
| get the replication lag. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| <function>pg_current_wal_lsn</function> displays the current write-ahead |
| log write location in the same format used by the above functions. |
| Similarly, <function>pg_current_wal_insert_lsn</function> displays the |
| current write-ahead log insertion location |
| and <function>pg_current_wal_flush_lsn</function> displays the current |
| write-ahead log flush location. The insertion location is |
| the <quote>logical</quote> end of the write-ahead log at any instant, |
| while the write location is the end of what has actually been written out |
| from the server's internal buffers, and the flush location is the last |
| location known to be written to durable storage. The write location is the |
| end of what can be examined from outside the server, and is usually what |
| you want if you are interested in archiving partially-complete write-ahead |
| log files. The insertion and flush locations are made available primarily |
| for server debugging purposes. These are all read-only operations and do |
| not require superuser permissions. |
| </para> |
| |
| <para> |
| You can use <function>pg_walfile_name_offset</function> to extract the |
| corresponding write-ahead log file name and byte offset from |
| a <type>pg_lsn</type> value. For example: |
| <programlisting> |
| postgres=# SELECT * FROM pg_walfile_name_offset(pg_stop_backup()); |
| file_name | file_offset |
| --------------------------+------------- |
| 00000001000000000000000D | 4039624 |
| (1 row) |
| </programlisting> |
| Similarly, <function>pg_walfile_name</function> extracts just the write-ahead log file name. |
| When the given write-ahead log location is exactly at a write-ahead log file boundary, both |
| these functions return the name of the preceding write-ahead log file. |
| This is usually the desired behavior for managing write-ahead log archiving |
| behavior, since the preceding file is the last one that currently |
| needs to be archived. |
| </para> |
| |
| </sect2> |
| |
| <sect2 id="functions-recovery-control"> |
| <title>Recovery Control Functions</title> |
| |
| <para> |
| The functions shown in <xref |
| linkend="functions-recovery-info-table"/> provide information |
| about the current status of a standby server. |
| These functions may be executed both during recovery and in normal running. |
| </para> |
| |
| <table id="functions-recovery-info-table"> |
| <title>Recovery Information Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_is_in_recovery</primary> |
| </indexterm> |
| <function>pg_is_in_recovery</function> () |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Returns true if recovery is still in progress. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_last_wal_receive_lsn</primary> |
| </indexterm> |
| <function>pg_last_wal_receive_lsn</function> () |
| <returnvalue>pg_lsn</returnvalue> |
| </para> |
| <para> |
| Returns the last write-ahead log location that has been received and |
| synced to disk by streaming replication. While streaming replication |
| is in progress this will increase monotonically. If recovery has |
| completed then this will remain static at the location of the last WAL |
| record received and synced to disk during recovery. If streaming |
| replication is disabled, or if it has not yet started, the function |
| returns <literal>NULL</literal>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_last_wal_replay_lsn</primary> |
| </indexterm> |
| <function>pg_last_wal_replay_lsn</function> () |
| <returnvalue>pg_lsn</returnvalue> |
| </para> |
| <para> |
| Returns the last write-ahead log location that has been replayed |
| during recovery. If recovery is still in progress this will increase |
| monotonically. If recovery has completed then this will remain |
| static at the location of the last WAL record applied during recovery. |
| When the server has been started normally without recovery, the |
| function returns <literal>NULL</literal>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_last_xact_replay_timestamp</primary> |
| </indexterm> |
| <function>pg_last_xact_replay_timestamp</function> () |
| <returnvalue>timestamp with time zone</returnvalue> |
| </para> |
| <para> |
| Returns the time stamp of the last transaction replayed during |
| recovery. This is the time at which the commit or abort WAL record |
| for that transaction was generated on the primary. If no transactions |
| have been replayed during recovery, the function |
| returns <literal>NULL</literal>. Otherwise, if recovery is still in |
| progress this will increase monotonically. If recovery has completed |
| then this will remain static at the time of the last transaction |
| applied during recovery. When the server has been started normally |
| without recovery, the function returns <literal>NULL</literal>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_get_wal_resource_managers</primary> |
| </indexterm> |
| <function>pg_get_wal_resource_managers</function> () |
| <returnvalue>setof record</returnvalue> |
| ( <parameter>rm_id</parameter> <type>integer</type>, |
| <parameter>rm_name</parameter> <type>text</type>, |
| <parameter>rm_builtin</parameter> <type>boolean</type> ) |
| </para> |
| <para> |
| Returns the currently-loaded WAL resource managers in the system. The |
| column <parameter>rm_builtin</parameter> indicates whether it's a |
| built-in resource manager, or a custom resource manager loaded by an |
| extension. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| The functions shown in <xref |
| linkend="functions-recovery-control-table"/> control the progress of recovery. |
| These functions may be executed only during recovery. |
| </para> |
| |
| <table id="functions-recovery-control-table"> |
| <title>Recovery Control Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_is_wal_replay_paused</primary> |
| </indexterm> |
| <function>pg_is_wal_replay_paused</function> () |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Returns true if recovery pause is requested. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_get_wal_replay_pause_state</primary> |
| </indexterm> |
| <function>pg_get_wal_replay_pause_state</function> () |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Returns recovery pause state. The return values are <literal> |
| not paused</literal> if pause is not requested, <literal> |
| pause requested</literal> if pause is requested but recovery is |
| not yet paused, and <literal>paused</literal> if the recovery is |
| actually paused. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_promote</primary> |
| </indexterm> |
| <function>pg_promote</function> ( <parameter>wait</parameter> <type>boolean</type> <literal>DEFAULT</literal> <literal>true</literal>, <parameter>wait_seconds</parameter> <type>integer</type> <literal>DEFAULT</literal> <literal>60</literal> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Promotes a standby server to primary status. |
| With <parameter>wait</parameter> set to <literal>true</literal> (the |
| default), the function waits until promotion is completed |
| or <parameter>wait_seconds</parameter> seconds have passed, and |
| returns <literal>true</literal> if promotion is successful |
| and <literal>false</literal> otherwise. |
| If <parameter>wait</parameter> is set to <literal>false</literal>, the |
| function returns <literal>true</literal> immediately after sending a |
| <literal>SIGUSR1</literal> signal to the postmaster to trigger |
| promotion. |
| </para> |
| <para> |
| This function is restricted to superusers by default, but other users |
| can be granted EXECUTE to run the function. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_wal_replay_pause</primary> |
| </indexterm> |
| <function>pg_wal_replay_pause</function> () |
| <returnvalue>void</returnvalue> |
| </para> |
| <para> |
| Request to pause recovery. A request doesn't mean that recovery stops |
| right away. If you want a guarantee that recovery is actually paused, |
| you need to check for the recovery pause state returned by |
| <function>pg_get_wal_replay_pause_state()</function>. Note that |
| <function>pg_is_wal_replay_paused()</function> returns whether a request |
| is made. While recovery is paused, no further database changes are applied. |
| If hot standby is active, all new queries will see the same consistent |
| snapshot of the database, and no further query conflicts will be generated |
| until recovery is resumed. |
| </para> |
| <para> |
| This function is restricted to superusers by default, but other users |
| can be granted EXECUTE to run the function. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_wal_replay_resume</primary> |
| </indexterm> |
| <function>pg_wal_replay_resume</function> () |
| <returnvalue>void</returnvalue> |
| </para> |
| <para> |
| Restarts recovery if it was paused. |
| </para> |
| <para> |
| This function is restricted to superusers by default, but other users |
| can be granted EXECUTE to run the function. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| <function>pg_wal_replay_pause</function> and |
| <function>pg_wal_replay_resume</function> cannot be executed while |
| a promotion is ongoing. If a promotion is triggered while recovery |
| is paused, the paused state ends and promotion continues. |
| </para> |
| |
| <para> |
| If streaming replication is disabled, the paused state may continue |
| indefinitely without a problem. If streaming replication is in |
| progress then WAL records will continue to be received, which will |
| eventually fill available disk space, depending upon the duration of |
| the pause, the rate of WAL generation and available disk space. |
| </para> |
| |
| </sect2> |
| |
| <sect2 id="functions-snapshot-synchronization"> |
| <title>Snapshot Synchronization Functions</title> |
| |
| <para> |
| <productname>PostgreSQL</productname> allows database sessions to synchronize their |
| snapshots. A <firstterm>snapshot</firstterm> determines which data is visible to the |
| transaction that is using the snapshot. Synchronized snapshots are |
| necessary when two or more sessions need to see identical content in the |
| database. If two sessions just start their transactions independently, |
| there is always a possibility that some third transaction commits |
| between the executions of the two <command>START TRANSACTION</command> commands, |
| so that one session sees the effects of that transaction and the other |
| does not. |
| </para> |
| |
| <para> |
| To solve this problem, <productname>PostgreSQL</productname> allows a transaction to |
| <firstterm>export</firstterm> the snapshot it is using. As long as the exporting |
| transaction remains open, other transactions can <firstterm>import</firstterm> its |
| snapshot, and thereby be guaranteed that they see exactly the same view |
| of the database that the first transaction sees. But note that any |
| database changes made by any one of these transactions remain invisible |
| to the other transactions, as is usual for changes made by uncommitted |
| transactions. So the transactions are synchronized with respect to |
| pre-existing data, but act normally for changes they make themselves. |
| </para> |
| |
| <para> |
| Snapshots are exported with the <function>pg_export_snapshot</function> function, |
| shown in <xref linkend="functions-snapshot-synchronization-table"/>, and |
| imported with the <xref linkend="sql-set-transaction"/> command. |
| </para> |
| |
| <table id="functions-snapshot-synchronization-table"> |
| <title>Snapshot Synchronization Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_export_snapshot</primary> |
| </indexterm> |
| <function>pg_export_snapshot</function> () |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Saves the transaction's current snapshot and returns |
| a <type>text</type> string identifying the snapshot. This string must |
| be passed (outside the database) to clients that want to import the |
| snapshot. The snapshot is available for import only until the end of |
| the transaction that exported it. |
| </para> |
| <para> |
| A transaction can export more than one snapshot, if needed. Note that |
| doing so is only useful in <literal>READ COMMITTED</literal> |
| transactions, since in <literal>REPEATABLE READ</literal> and higher |
| isolation levels, transactions use the same snapshot throughout their |
| lifetime. Once a transaction has exported any snapshots, it cannot be |
| prepared with <xref linkend="sql-prepare-transaction"/>. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| </sect2> |
| |
| <sect2 id="functions-replication"> |
| <title>Replication Management Functions</title> |
| |
| <para> |
| The functions shown |
| in <xref linkend="functions-replication-table"/> are for |
| controlling and interacting with replication features. |
| See <xref linkend="streaming-replication"/>, |
| <xref linkend="streaming-replication-slots"/>, and |
| <xref linkend="replication-origins"/> |
| for information about the underlying features. |
| Use of functions for replication origin is only allowed to the |
| superuser by default, but may be allowed to other users by using the |
| <literal>GRANT</literal> command. |
| Use of functions for replication slots is restricted to superusers |
| and users having <literal>REPLICATION</literal> privilege. |
| </para> |
| |
| <para> |
| Many of these functions have equivalent commands in the replication |
| protocol; see <xref linkend="protocol-replication"/>. |
| </para> |
| |
| <para> |
| The functions described in |
| <xref linkend="functions-admin-backup"/>, |
| <xref linkend="functions-recovery-control"/>, and |
| <xref linkend="functions-snapshot-synchronization"/> |
| are also relevant for replication. |
| </para> |
| |
| <table id="functions-replication-table"> |
| <title>Replication Management Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_create_physical_replication_slot</primary> |
| </indexterm> |
| <function>pg_create_physical_replication_slot</function> ( <parameter>slot_name</parameter> <type>name</type> <optional>, <parameter>immediately_reserve</parameter> <type>boolean</type>, <parameter>temporary</parameter> <type>boolean</type> </optional> ) |
| <returnvalue>record</returnvalue> |
| ( <parameter>slot_name</parameter> <type>name</type>, |
| <parameter>lsn</parameter> <type>pg_lsn</type> ) |
| </para> |
| <para> |
| Creates a new physical replication slot named |
| <parameter>slot_name</parameter>. The optional second parameter, |
| when <literal>true</literal>, specifies that the <acronym>LSN</acronym> for this |
| replication slot be reserved immediately; otherwise |
| the <acronym>LSN</acronym> is reserved on first connection from a streaming |
| replication client. Streaming changes from a physical slot is only |
| possible with the streaming-replication protocol — |
| see <xref linkend="protocol-replication"/>. The optional third |
| parameter, <parameter>temporary</parameter>, when set to true, specifies that |
| the slot should not be permanently stored to disk and is only meant |
| for use by the current session. Temporary slots are also |
| released upon any error. This function corresponds |
| to the replication protocol command <literal>CREATE_REPLICATION_SLOT |
| ... PHYSICAL</literal>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_drop_replication_slot</primary> |
| </indexterm> |
| <function>pg_drop_replication_slot</function> ( <parameter>slot_name</parameter> <type>name</type> ) |
| <returnvalue>void</returnvalue> |
| </para> |
| <para> |
| Drops the physical or logical replication slot |
| named <parameter>slot_name</parameter>. Same as replication protocol |
| command <literal>DROP_REPLICATION_SLOT</literal>. For logical slots, this must |
| be called while connected to the same database the slot was created on. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_create_logical_replication_slot</primary> |
| </indexterm> |
| <function>pg_create_logical_replication_slot</function> ( <parameter>slot_name</parameter> <type>name</type>, <parameter>plugin</parameter> <type>name</type> <optional>, <parameter>temporary</parameter> <type>boolean</type>, <parameter>two_phase</parameter> <type>boolean</type> </optional> ) |
| <returnvalue>record</returnvalue> |
| ( <parameter>slot_name</parameter> <type>name</type>, |
| <parameter>lsn</parameter> <type>pg_lsn</type> ) |
| </para> |
| <para> |
| Creates a new logical (decoding) replication slot named |
| <parameter>slot_name</parameter> using the output plugin |
| <parameter>plugin</parameter>. The optional third |
| parameter, <parameter>temporary</parameter>, when set to true, specifies that |
| the slot should not be permanently stored to disk and is only meant |
| for use by the current session. Temporary slots are also |
| released upon any error. The optional fourth parameter, |
| <parameter>two_phase</parameter>, when set to true, specifies |
| that the decoding of prepared transactions is enabled for this |
| slot. A call to this function has the same effect as the replication |
| protocol command <literal>CREATE_REPLICATION_SLOT ... LOGICAL</literal>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_copy_physical_replication_slot</primary> |
| </indexterm> |
| <function>pg_copy_physical_replication_slot</function> ( <parameter>src_slot_name</parameter> <type>name</type>, <parameter>dst_slot_name</parameter> <type>name</type> <optional>, <parameter>temporary</parameter> <type>boolean</type> </optional> ) |
| <returnvalue>record</returnvalue> |
| ( <parameter>slot_name</parameter> <type>name</type>, |
| <parameter>lsn</parameter> <type>pg_lsn</type> ) |
| </para> |
| <para> |
| Copies an existing physical replication slot named <parameter>src_slot_name</parameter> |
| to a physical replication slot named <parameter>dst_slot_name</parameter>. |
| The copied physical slot starts to reserve WAL from the same <acronym>LSN</acronym> as the |
| source slot. |
| <parameter>temporary</parameter> is optional. If <parameter>temporary</parameter> |
| is omitted, the same value as the source slot is used. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_copy_logical_replication_slot</primary> |
| </indexterm> |
| <function>pg_copy_logical_replication_slot</function> ( <parameter>src_slot_name</parameter> <type>name</type>, <parameter>dst_slot_name</parameter> <type>name</type> <optional>, <parameter>temporary</parameter> <type>boolean</type> <optional>, <parameter>plugin</parameter> <type>name</type> </optional></optional> ) |
| <returnvalue>record</returnvalue> |
| ( <parameter>slot_name</parameter> <type>name</type>, |
| <parameter>lsn</parameter> <type>pg_lsn</type> ) |
| </para> |
| <para> |
| Copies an existing logical replication slot |
| named <parameter>src_slot_name</parameter> to a logical replication |
| slot named <parameter>dst_slot_name</parameter>, optionally changing |
| the output plugin and persistence. The copied logical slot starts |
| from the same <acronym>LSN</acronym> as the source logical slot. Both |
| <parameter>temporary</parameter> and <parameter>plugin</parameter> are |
| optional; if they are omitted, the values of the source slot are used. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_logical_slot_get_changes</primary> |
| </indexterm> |
| <function>pg_logical_slot_get_changes</function> ( <parameter>slot_name</parameter> <type>name</type>, <parameter>upto_lsn</parameter> <type>pg_lsn</type>, <parameter>upto_nchanges</parameter> <type>integer</type>, <literal>VARIADIC</literal> <parameter>options</parameter> <type>text[]</type> ) |
| <returnvalue>setof record</returnvalue> |
| ( <parameter>lsn</parameter> <type>pg_lsn</type>, |
| <parameter>xid</parameter> <type>xid</type>, |
| <parameter>data</parameter> <type>text</type> ) |
| </para> |
| <para> |
| Returns changes in the slot <parameter>slot_name</parameter>, starting |
| from the point from which changes have been consumed last. If |
| <parameter>upto_lsn</parameter> |
| and <parameter>upto_nchanges</parameter> are NULL, |
| logical decoding will continue until end of WAL. If |
| <parameter>upto_lsn</parameter> is non-NULL, decoding will include only |
| those transactions which commit prior to the specified LSN. If |
| <parameter>upto_nchanges</parameter> is non-NULL, decoding will |
| stop when the number of rows produced by decoding exceeds |
| the specified value. Note, however, that the actual number of |
| rows returned may be larger, since this limit is only checked after |
| adding the rows produced when decoding each new transaction commit. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_logical_slot_peek_changes</primary> |
| </indexterm> |
| <function>pg_logical_slot_peek_changes</function> ( <parameter>slot_name</parameter> <type>name</type>, <parameter>upto_lsn</parameter> <type>pg_lsn</type>, <parameter>upto_nchanges</parameter> <type>integer</type>, <literal>VARIADIC</literal> <parameter>options</parameter> <type>text[]</type> ) |
| <returnvalue>setof record</returnvalue> |
| ( <parameter>lsn</parameter> <type>pg_lsn</type>, |
| <parameter>xid</parameter> <type>xid</type>, |
| <parameter>data</parameter> <type>text</type> ) |
| </para> |
| <para> |
| Behaves just like |
| the <function>pg_logical_slot_get_changes()</function> function, |
| except that changes are not consumed; that is, they will be returned |
| again on future calls. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_logical_slot_get_binary_changes</primary> |
| </indexterm> |
| <function>pg_logical_slot_get_binary_changes</function> ( <parameter>slot_name</parameter> <type>name</type>, <parameter>upto_lsn</parameter> <type>pg_lsn</type>, <parameter>upto_nchanges</parameter> <type>integer</type>, <literal>VARIADIC</literal> <parameter>options</parameter> <type>text[]</type> ) |
| <returnvalue>setof record</returnvalue> |
| ( <parameter>lsn</parameter> <type>pg_lsn</type>, |
| <parameter>xid</parameter> <type>xid</type>, |
| <parameter>data</parameter> <type>bytea</type> ) |
| </para> |
| <para> |
| Behaves just like |
| the <function>pg_logical_slot_get_changes()</function> function, |
| except that changes are returned as <type>bytea</type>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_logical_slot_peek_binary_changes</primary> |
| </indexterm> |
| <function>pg_logical_slot_peek_binary_changes</function> ( <parameter>slot_name</parameter> <type>name</type>, <parameter>upto_lsn</parameter> <type>pg_lsn</type>, <parameter>upto_nchanges</parameter> <type>integer</type>, <literal>VARIADIC</literal> <parameter>options</parameter> <type>text[]</type> ) |
| <returnvalue>setof record</returnvalue> |
| ( <parameter>lsn</parameter> <type>pg_lsn</type>, |
| <parameter>xid</parameter> <type>xid</type>, |
| <parameter>data</parameter> <type>bytea</type> ) |
| </para> |
| <para> |
| Behaves just like |
| the <function>pg_logical_slot_peek_changes()</function> function, |
| except that changes are returned as <type>bytea</type>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_replication_slot_advance</primary> |
| </indexterm> |
| <function>pg_replication_slot_advance</function> ( <parameter>slot_name</parameter> <type>name</type>, <parameter>upto_lsn</parameter> <type>pg_lsn</type> ) |
| <returnvalue>record</returnvalue> |
| ( <parameter>slot_name</parameter> <type>name</type>, |
| <parameter>end_lsn</parameter> <type>pg_lsn</type> ) |
| </para> |
| <para> |
| Advances the current confirmed position of a replication slot named |
| <parameter>slot_name</parameter>. The slot will not be moved backwards, |
| and it will not be moved beyond the current insert location. Returns |
| the name of the slot and the actual position that it was advanced to. |
| The updated slot position information is written out at the next |
| checkpoint if any advancing is done. So in the event of a crash, the |
| slot may return to an earlier position. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry id="pg-replication-origin-create" role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_replication_origin_create</primary> |
| </indexterm> |
| <function>pg_replication_origin_create</function> ( <parameter>node_name</parameter> <type>text</type> ) |
| <returnvalue>oid</returnvalue> |
| </para> |
| <para> |
| Creates a replication origin with the given external |
| name, and returns the internal ID assigned to it. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry id="pg-replication-origin-drop" role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_replication_origin_drop</primary> |
| </indexterm> |
| <function>pg_replication_origin_drop</function> ( <parameter>node_name</parameter> <type>text</type> ) |
| <returnvalue>void</returnvalue> |
| </para> |
| <para> |
| Deletes a previously-created replication origin, including any |
| associated replay progress. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_replication_origin_oid</primary> |
| </indexterm> |
| <function>pg_replication_origin_oid</function> ( <parameter>node_name</parameter> <type>text</type> ) |
| <returnvalue>oid</returnvalue> |
| </para> |
| <para> |
| Looks up a replication origin by name and returns the internal ID. If |
| no such replication origin is found, <literal>NULL</literal> is |
| returned. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry id="pg-replication-origin-session-setup" role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_replication_origin_session_setup</primary> |
| </indexterm> |
| <function>pg_replication_origin_session_setup</function> ( <parameter>node_name</parameter> <type>text</type> ) |
| <returnvalue>void</returnvalue> |
| </para> |
| <para> |
| Marks the current session as replaying from the given |
| origin, allowing replay progress to be tracked. |
| Can only be used if no origin is currently selected. |
| Use <function>pg_replication_origin_session_reset</function> to undo. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_replication_origin_session_reset</primary> |
| </indexterm> |
| <function>pg_replication_origin_session_reset</function> () |
| <returnvalue>void</returnvalue> |
| </para> |
| <para> |
| Cancels the effects |
| of <function>pg_replication_origin_session_setup()</function>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_replication_origin_session_is_setup</primary> |
| </indexterm> |
| <function>pg_replication_origin_session_is_setup</function> () |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Returns true if a replication origin has been selected in the |
| current session. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry id="pg-replication-origin-session-progress" role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_replication_origin_session_progress</primary> |
| </indexterm> |
| <function>pg_replication_origin_session_progress</function> ( <parameter>flush</parameter> <type>boolean</type> ) |
| <returnvalue>pg_lsn</returnvalue> |
| </para> |
| <para> |
| Returns the replay location for the replication origin selected in |
| the current session. The parameter <parameter>flush</parameter> |
| determines whether the corresponding local transaction will be |
| guaranteed to have been flushed to disk or not. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry id="pg-replication-origin-xact-setup" role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_replication_origin_xact_setup</primary> |
| </indexterm> |
| <function>pg_replication_origin_xact_setup</function> ( <parameter>origin_lsn</parameter> <type>pg_lsn</type>, <parameter>origin_timestamp</parameter> <type>timestamp with time zone</type> ) |
| <returnvalue>void</returnvalue> |
| </para> |
| <para> |
| Marks the current transaction as replaying a transaction that has |
| committed at the given <acronym>LSN</acronym> and timestamp. Can |
| only be called when a replication origin has been selected |
| using <function>pg_replication_origin_session_setup</function>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry id="pg-replication-origin-xact-reset" role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_replication_origin_xact_reset</primary> |
| </indexterm> |
| <function>pg_replication_origin_xact_reset</function> () |
| <returnvalue>void</returnvalue> |
| </para> |
| <para> |
| Cancels the effects of |
| <function>pg_replication_origin_xact_setup()</function>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry id="pg-replication-origin-advance" role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_replication_origin_advance</primary> |
| </indexterm> |
| <function>pg_replication_origin_advance</function> ( <parameter>node_name</parameter> <type>text</type>, <parameter>lsn</parameter> <type>pg_lsn</type> ) |
| <returnvalue>void</returnvalue> |
| </para> |
| <para> |
| Sets replication progress for the given node to the given |
| location. This is primarily useful for setting up the initial |
| location, or setting a new location after configuration changes and |
| similar. Be aware that careless use of this function can lead to |
| inconsistently replicated data. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry id="pg-replication-origin-progress" role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_replication_origin_progress</primary> |
| </indexterm> |
| <function>pg_replication_origin_progress</function> ( <parameter>node_name</parameter> <type>text</type>, <parameter>flush</parameter> <type>boolean</type> ) |
| <returnvalue>pg_lsn</returnvalue> |
| </para> |
| <para> |
| Returns the replay location for the given replication origin. The |
| parameter <parameter>flush</parameter> determines whether the |
| corresponding local transaction will be guaranteed to have been |
| flushed to disk or not. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_logical_emit_message</primary> |
| </indexterm> |
| <function>pg_logical_emit_message</function> ( <parameter>transactional</parameter> <type>boolean</type>, <parameter>prefix</parameter> <type>text</type>, <parameter>content</parameter> <type>text</type> ) |
| <returnvalue>pg_lsn</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>pg_logical_emit_message</function> ( <parameter>transactional</parameter> <type>boolean</type>, <parameter>prefix</parameter> <type>text</type>, <parameter>content</parameter> <type>bytea</type> ) |
| <returnvalue>pg_lsn</returnvalue> |
| </para> |
| <para> |
| Emits a logical decoding message. This can be used to pass generic |
| messages to logical decoding plugins through |
| WAL. The <parameter>transactional</parameter> parameter specifies if |
| the message should be part of the current transaction, or if it should |
| be written immediately and decoded as soon as the logical decoder |
| reads the record. The <parameter>prefix</parameter> parameter is a |
| textual prefix that can be used by logical decoding plugins to easily |
| recognize messages that are interesting for them. |
| The <parameter>content</parameter> parameter is the content of the |
| message, given either in text or binary form. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| </sect2> |
| |
| <sect2 id="functions-admin-dbobject"> |
| <title>Database Object Management Functions</title> |
| |
| <para> |
| The functions shown in <xref linkend="functions-admin-dbsize"/> calculate |
| the disk space usage of database objects, or assist in presentation |
| or understanding of usage results. <literal>bigint</literal> results |
| are measured in bytes. If an OID that does |
| not represent an existing object is passed to one of these |
| functions, <literal>NULL</literal> is returned. |
| </para> |
| |
| <table id="functions-admin-dbsize"> |
| <title>Database Object Size Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_column_size</primary> |
| </indexterm> |
| <function>pg_column_size</function> ( <type>"any"</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Shows the number of bytes used to store any individual data value. If |
| applied directly to a table column value, this reflects any |
| compression that was done. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_column_compression</primary> |
| </indexterm> |
| <function>pg_column_compression</function> ( <type>"any"</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Shows the compression algorithm that was used to compress |
| an individual variable-length value. Returns <literal>NULL</literal> |
| if the value is not compressed. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_database_size</primary> |
| </indexterm> |
| <function>pg_database_size</function> ( <type>name</type> ) |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>pg_database_size</function> ( <type>oid</type> ) |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para> |
| Computes the total disk space used by the database with the specified |
| name or OID. To use this function, you must |
| have <literal>CONNECT</literal> privilege on the specified database |
| (which is granted by default) or be a member of |
| the <literal>pg_read_all_stats</literal> role. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_indexes_size</primary> |
| </indexterm> |
| <function>pg_indexes_size</function> ( <type>regclass</type> ) |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para> |
| Computes the total disk space used by indexes attached to the |
| specified table. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_relation_size</primary> |
| </indexterm> |
| <function>pg_relation_size</function> ( <parameter>relation</parameter> <type>regclass</type> <optional>, <parameter>fork</parameter> <type>text</type> </optional> ) |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para> |
| Computes the disk space used by one <quote>fork</quote> of the |
| specified relation. (Note that for most purposes it is more |
| convenient to use the higher-level |
| functions <function>pg_total_relation_size</function> |
| or <function>pg_table_size</function>, which sum the sizes of all |
| forks.) With one argument, this returns the size of the main data |
| fork of the relation. The second argument can be provided to specify |
| which fork to examine: |
| <itemizedlist spacing="compact"> |
| <listitem> |
| <para> |
| <literal>main</literal> returns the size of the main |
| data fork of the relation. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| <literal>fsm</literal> returns the size of the Free Space Map |
| (see <xref linkend="storage-fsm"/>) associated with the relation. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| <literal>vm</literal> returns the size of the Visibility Map |
| (see <xref linkend="storage-vm"/>) associated with the relation. |
| </para> |
| </listitem> |
| <listitem> |
| <para> |
| <literal>init</literal> returns the size of the initialization |
| fork, if any, associated with the relation. |
| </para> |
| </listitem> |
| </itemizedlist> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_size_bytes</primary> |
| </indexterm> |
| <function>pg_size_bytes</function> ( <type>text</type> ) |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para> |
| Converts a size in human-readable format (as returned |
| by <function>pg_size_pretty</function>) into bytes. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_size_pretty</primary> |
| </indexterm> |
| <function>pg_size_pretty</function> ( <type>bigint</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>pg_size_pretty</function> ( <type>numeric</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Converts a size in bytes into a more easily human-readable format with |
| size units (bytes, kB, MB, GB or TB as appropriate). Note that the |
| units are powers of 2 rather than powers of 10, so 1kB is 1024 bytes, |
| 1MB is 1024<superscript>2</superscript> = 1048576 bytes, and so on. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_table_size</primary> |
| </indexterm> |
| <function>pg_table_size</function> ( <type>regclass</type> ) |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para> |
| Computes the disk space used by the specified table, excluding indexes |
| (but including its TOAST table if any, free space map, and visibility |
| map). |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_tablespace_size</primary> |
| </indexterm> |
| <function>pg_tablespace_size</function> ( <type>name</type> ) |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>pg_tablespace_size</function> ( <type>oid</type> ) |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para> |
| Computes the total disk space used in the tablespace with the |
| specified name or OID. To use this function, you must |
| have <literal>CREATE</literal> privilege on the specified tablespace |
| or be a member of the <literal>pg_read_all_stats</literal> role, |
| unless it is the default tablespace for the current database. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_total_relation_size</primary> |
| </indexterm> |
| <function>pg_total_relation_size</function> ( <type>regclass</type> ) |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para> |
| Computes the total disk space used by the specified table, including |
| all indexes and <acronym>TOAST</acronym> data. The result is |
| equivalent to <function>pg_table_size</function> |
| <literal>+</literal> <function>pg_indexes_size</function>. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| The functions above that operate on tables or indexes accept a |
| <type>regclass</type> argument, which is simply the OID of the table or index |
| in the <structname>pg_class</structname> system catalog. You do not have to look up |
| the OID by hand, however, since the <type>regclass</type> data type's input |
| converter will do the work for you. See <xref linkend="datatype-oid"/> |
| for details. |
| </para> |
| |
| <para> |
| The functions shown in <xref linkend="functions-admin-dblocation"/> assist |
| in identifying the specific disk files associated with database objects. |
| </para> |
| |
| <table id="functions-admin-dblocation"> |
| <title>Database Object Location Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_relation_filenode</primary> |
| </indexterm> |
| <function>pg_relation_filenode</function> ( <parameter>relation</parameter> <type>regclass</type> ) |
| <returnvalue>oid</returnvalue> |
| </para> |
| <para> |
| Returns the <quote>filenode</quote> number currently assigned to the |
| specified relation. The filenode is the base component of the file |
| name(s) used for the relation (see |
| <xref linkend="storage-file-layout"/> for more information). |
| For most relations the result is the same as |
| <structname>pg_class</structname>.<structfield>relfilenode</structfield>, |
| but for certain system catalogs <structfield>relfilenode</structfield> |
| is zero and this function must be used to get the correct value. The |
| function returns NULL if passed a relation that does not have storage, |
| such as a view. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_relation_filepath</primary> |
| </indexterm> |
| <function>pg_relation_filepath</function> ( <parameter>relation</parameter> <type>regclass</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Returns the entire file path name (relative to the database cluster's |
| data directory, <varname>PGDATA</varname>) of the relation. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_filenode_relation</primary> |
| </indexterm> |
| <function>pg_filenode_relation</function> ( <parameter>tablespace</parameter> <type>oid</type>, <parameter>filenode</parameter> <type>oid</type> ) |
| <returnvalue>regclass</returnvalue> |
| </para> |
| <para> |
| Returns a relation's OID given the tablespace OID and filenode it is |
| stored under. This is essentially the inverse mapping of |
| <function>pg_relation_filepath</function>. For a relation in the |
| database's default tablespace, the tablespace can be specified as zero. |
| Returns <literal>NULL</literal> if no relation in the current database |
| is associated with the given values. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| <xref linkend="functions-admin-collation"/> lists functions used to manage |
| collations. |
| </para> |
| |
| <table id="functions-admin-collation"> |
| <title>Collation Management Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_collation_actual_version</primary> |
| </indexterm> |
| <function>pg_collation_actual_version</function> ( <type>oid</type> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Returns the actual version of the collation object as it is currently |
| installed in the operating system. If this is different from the |
| value in |
| <structname>pg_collation</structname>.<structfield>collversion</structfield>, |
| then objects depending on the collation might need to be rebuilt. See |
| also <xref linkend="sql-altercollation"/>. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_import_system_collations</primary> |
| </indexterm> |
| <function>pg_import_system_collations</function> ( <parameter>schema</parameter> <type>regnamespace</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Adds collations to the system |
| catalog <structname>pg_collation</structname> based on all the locales |
| it finds in the operating system. This is |
| what <command>initdb</command> uses; see |
| <xref linkend="collation-managing"/> for more details. If additional |
| locales are installed into the operating system later on, this |
| function can be run again to add collations for the new locales. |
| Locales that match existing entries |
| in <structname>pg_collation</structname> will be skipped. (But |
| collation objects based on locales that are no longer present in the |
| operating system are not removed by this function.) |
| The <parameter>schema</parameter> parameter would typically |
| be <literal>pg_catalog</literal>, but that is not a requirement; the |
| collations could be installed into some other schema as well. The |
| function returns the number of new collation objects it created. |
| Use of this function is restricted to superusers. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| <xref linkend="functions-info-partition"/> lists functions that provide |
| information about the structure of partitioned tables. |
| </para> |
| |
| <table id="functions-info-partition"> |
| <title>Partitioning Information Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_partition_tree</primary> |
| </indexterm> |
| <function>pg_partition_tree</function> ( <type>regclass</type> ) |
| <returnvalue>setof record</returnvalue> |
| ( <parameter>relid</parameter> <type>regclass</type>, |
| <parameter>parentrelid</parameter> <type>regclass</type>, |
| <parameter>isleaf</parameter> <type>boolean</type>, |
| <parameter>level</parameter> <type>integer</type> ) |
| </para> |
| <para> |
| Lists the tables or indexes in the partition tree of the |
| given partitioned table or partitioned index, with one row for each |
| partition. Information provided includes the OID of the partition, |
| the OID of its immediate parent, a boolean value telling if the |
| partition is a leaf, and an integer telling its level in the hierarchy. |
| The level value is 0 for the input table or index, 1 for its |
| immediate child partitions, 2 for their partitions, and so on. |
| Returns no rows if the relation does not exist or is not a partition |
| or partitioned table. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_partition_ancestors</primary> |
| </indexterm> |
| <function>pg_partition_ancestors</function> ( <type>regclass</type> ) |
| <returnvalue>setof regclass</returnvalue> |
| </para> |
| <para> |
| Lists the ancestor relations of the given partition, |
| including the relation itself. Returns no rows if the relation |
| does not exist or is not a partition or partitioned table. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_partition_root</primary> |
| </indexterm> |
| <function>pg_partition_root</function> ( <type>regclass</type> ) |
| <returnvalue>regclass</returnvalue> |
| </para> |
| <para> |
| Returns the top-most parent of the partition tree to which the given |
| relation belongs. Returns <literal>NULL</literal> if the relation |
| does not exist or is not a partition or partitioned table. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| For example, to check the total size of the data contained in a |
| partitioned table <structname>measurement</structname>, one could use the |
| following query: |
| <programlisting> |
| SELECT pg_size_pretty(sum(pg_relation_size(relid))) AS total_size |
| FROM pg_partition_tree('measurement'); |
| </programlisting> |
| </para> |
| |
| </sect2> |
| |
| <sect2 id="functions-admin-index"> |
| <title>Index Maintenance Functions</title> |
| |
| <para> |
| <xref linkend="functions-admin-index-table"/> shows the functions |
| available for index maintenance tasks. (Note that these maintenance |
| tasks are normally done automatically by autovacuum; use of these |
| functions is only required in special cases.) |
| These functions cannot be executed during recovery. |
| Use of these functions is restricted to superusers and the owner |
| of the given index. |
| </para> |
| |
| <table id="functions-admin-index-table"> |
| <title>Index Maintenance Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>brin_summarize_new_values</primary> |
| </indexterm> |
| <function>brin_summarize_new_values</function> ( <parameter>index</parameter> <type>regclass</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Scans the specified BRIN index to find page ranges in the base table |
| that are not currently summarized by the index; for any such range it |
| creates a new summary index tuple by scanning those table pages. |
| Returns the number of new page range summaries that were inserted |
| into the index. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>brin_summarize_range</primary> |
| </indexterm> |
| <function>brin_summarize_range</function> ( <parameter>index</parameter> <type>regclass</type>, <parameter>blockNumber</parameter> <type>bigint</type> ) |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Summarizes the page range covering the given block, if not already |
| summarized. This is |
| like <function>brin_summarize_new_values</function> except that it |
| only processes the page range that covers the given table block number. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>brin_desummarize_range</primary> |
| </indexterm> |
| <function>brin_desummarize_range</function> ( <parameter>index</parameter> <type>regclass</type>, <parameter>blockNumber</parameter> <type>bigint</type> ) |
| <returnvalue>void</returnvalue> |
| </para> |
| <para> |
| Removes the BRIN index tuple that summarizes the page range covering |
| the given table block, if there is one. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>gin_clean_pending_list</primary> |
| </indexterm> |
| <function>gin_clean_pending_list</function> ( <parameter>index</parameter> <type>regclass</type> ) |
| <returnvalue>bigint</returnvalue> |
| </para> |
| <para> |
| Cleans up the <quote>pending</quote> list of the specified GIN index |
| by moving entries in it, in bulk, to the main GIN data structure. |
| Returns the number of pages removed from the pending list. |
| If the argument is a GIN index built with |
| the <literal>fastupdate</literal> option disabled, no cleanup happens |
| and the result is zero, because the index doesn't have a pending list. |
| See <xref linkend="gin-fast-update"/> and <xref linkend="gin-tips"/> |
| for details about the pending list and <literal>fastupdate</literal> |
| option. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| </sect2> |
| |
| <sect2 id="functions-admin-genfile"> |
| <title>Generic File Access Functions</title> |
| |
| <para> |
| The functions shown in <xref |
| linkend="functions-admin-genfile-table"/> provide native access to |
| files on the machine hosting the server. Only files within the |
| database cluster directory and the <varname>log_directory</varname> can be |
| accessed, unless the user is a superuser or is granted the role |
| <literal>pg_read_server_files</literal>. Use a relative path for files in |
| the cluster directory, and a path matching the <varname>log_directory</varname> |
| configuration setting for log files. |
| </para> |
| |
| <para> |
| Note that granting users the EXECUTE privilege on |
| <function>pg_read_file()</function>, or related functions, allows them the |
| ability to read any file on the server that the database server process can |
| read; these functions bypass all in-database privilege checks. This means |
| that, for example, a user with such access is able to read the contents of |
| the <structname>pg_authid</structname> table where authentication |
| information is stored, as well as read any table data in the database. |
| Therefore, granting access to these functions should be carefully |
| considered. |
| </para> |
| |
| <para> |
| Some of these functions take an optional <parameter>missing_ok</parameter> |
| parameter, which specifies the behavior when the file or directory does |
| not exist. If <literal>true</literal>, the function |
| returns <literal>NULL</literal> or an empty result set, as appropriate. |
| If <literal>false</literal>, an error is raised. The default |
| is <literal>false</literal>. |
| </para> |
| |
| <table id="functions-admin-genfile-table"> |
| <title>Generic File Access Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_ls_dir</primary> |
| </indexterm> |
| <function>pg_ls_dir</function> ( <parameter>dirname</parameter> <type>text</type> <optional>, <parameter>missing_ok</parameter> <type>boolean</type>, <parameter>include_dot_dirs</parameter> <type>boolean</type> </optional> ) |
| <returnvalue>setof text</returnvalue> |
| </para> |
| <para> |
| Returns the names of all files (and directories and other special |
| files) in the specified |
| directory. The <parameter>include_dot_dirs</parameter> parameter |
| indicates whether <quote>.</quote> and <quote>..</quote> are to be |
| included in the result set; the default is to exclude them. Including |
| them can be useful when <parameter>missing_ok</parameter> |
| is <literal>true</literal>, to distinguish an empty directory from a |
| non-existent directory. |
| </para> |
| <para> |
| This function is restricted to superusers by default, but other users |
| can be granted EXECUTE to run the function. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_ls_logdir</primary> |
| </indexterm> |
| <function>pg_ls_logdir</function> () |
| <returnvalue>setof record</returnvalue> |
| ( <parameter>name</parameter> <type>text</type>, |
| <parameter>size</parameter> <type>bigint</type>, |
| <parameter>modification</parameter> <type>timestamp with time zone</type> ) |
| </para> |
| <para> |
| Returns the name, size, and last modification time (mtime) of each |
| ordinary file in the server's log directory. Filenames beginning with |
| a dot, directories, and other special files are excluded. |
| </para> |
| <para> |
| This function is restricted to superusers and members of |
| the <literal>pg_monitor</literal> role by default, but other users can |
| be granted EXECUTE to run the function. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_ls_waldir</primary> |
| </indexterm> |
| <function>pg_ls_waldir</function> () |
| <returnvalue>setof record</returnvalue> |
| ( <parameter>name</parameter> <type>text</type>, |
| <parameter>size</parameter> <type>bigint</type>, |
| <parameter>modification</parameter> <type>timestamp with time zone</type> ) |
| </para> |
| <para> |
| Returns the name, size, and last modification time (mtime) of each |
| ordinary file in the server's write-ahead log (WAL) directory. |
| Filenames beginning with a dot, directories, and other special files |
| are excluded. |
| </para> |
| <para> |
| This function is restricted to superusers and members of |
| the <literal>pg_monitor</literal> role by default, but other users can |
| be granted EXECUTE to run the function. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_ls_archive_statusdir</primary> |
| </indexterm> |
| <function>pg_ls_archive_statusdir</function> () |
| <returnvalue>setof record</returnvalue> |
| ( <parameter>name</parameter> <type>text</type>, |
| <parameter>size</parameter> <type>bigint</type>, |
| <parameter>modification</parameter> <type>timestamp with time zone</type> ) |
| </para> |
| <para> |
| Returns the name, size, and last modification time (mtime) of each |
| ordinary file in the server's WAL archive status directory |
| (<filename>pg_wal/archive_status</filename>). Filenames beginning |
| with a dot, directories, and other special files are excluded. |
| </para> |
| <para> |
| This function is restricted to superusers and members of |
| the <literal>pg_monitor</literal> role by default, but other users can |
| be granted EXECUTE to run the function. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| |
| <indexterm> |
| <primary>pg_ls_tmpdir</primary> |
| </indexterm> |
| <function>pg_ls_tmpdir</function> ( <optional> <parameter>tablespace</parameter> <type>oid</type> </optional> ) |
| <returnvalue>setof record</returnvalue> |
| ( <parameter>name</parameter> <type>text</type>, |
| <parameter>size</parameter> <type>bigint</type>, |
| <parameter>modification</parameter> <type>timestamp with time zone</type> ) |
| </para> |
| <para> |
| Returns the name, size, and last modification time (mtime) of each |
| ordinary file in the temporary file directory for the |
| specified <parameter>tablespace</parameter>. |
| If <parameter>tablespace</parameter> is not provided, |
| the <literal>pg_default</literal> tablespace is examined. Filenames |
| beginning with a dot, directories, and other special files are |
| excluded. |
| </para> |
| <para> |
| This function is restricted to superusers and members of |
| the <literal>pg_monitor</literal> role by default, but other users can |
| be granted EXECUTE to run the function. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_read_file</primary> |
| </indexterm> |
| <function>pg_read_file</function> ( <parameter>filename</parameter> <type>text</type> <optional>, <parameter>offset</parameter> <type>bigint</type>, <parameter>length</parameter> <type>bigint</type> <optional>, <parameter>missing_ok</parameter> <type>boolean</type> </optional></optional> ) |
| <returnvalue>text</returnvalue> |
| </para> |
| <para> |
| Returns all or part of a text file, starting at the |
| given byte <parameter>offset</parameter>, returning at |
| most <parameter>length</parameter> bytes (less if the end of file is |
| reached first). If <parameter>offset</parameter> is negative, it is |
| relative to the end of the file. If <parameter>offset</parameter> |
| and <parameter>length</parameter> are omitted, the entire file is |
| returned. The bytes read from the file are interpreted as a string in |
| the database's encoding; an error is thrown if they are not valid in |
| that encoding. |
| </para> |
| <para> |
| This function is restricted to superusers by default, but other users |
| can be granted EXECUTE to run the function. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_read_binary_file</primary> |
| </indexterm> |
| <function>pg_read_binary_file</function> ( <parameter>filename</parameter> <type>text</type> <optional>, <parameter>offset</parameter> <type>bigint</type>, <parameter>length</parameter> <type>bigint</type> <optional>, <parameter>missing_ok</parameter> <type>boolean</type> </optional></optional> ) |
| <returnvalue>bytea</returnvalue> |
| </para> |
| <para> |
| Returns all or part of a file. This function is identical to |
| <function>pg_read_file</function> except that it can read arbitrary |
| binary data, returning the result as <type>bytea</type> |
| not <type>text</type>; accordingly, no encoding checks are performed. |
| </para> |
| <para> |
| This function is restricted to superusers by default, but other users |
| can be granted EXECUTE to run the function. |
| </para> |
| <para> |
| In combination with the <function>convert_from</function> function, |
| this function can be used to read a text file in a specified encoding |
| and convert to the database's encoding: |
| <programlisting> |
| SELECT convert_from(pg_read_binary_file('file_in_utf8.txt'), 'UTF8'); |
| </programlisting> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_stat_file</primary> |
| </indexterm> |
| <function>pg_stat_file</function> ( <parameter>filename</parameter> <type>text</type> <optional>, <parameter>missing_ok</parameter> <type>boolean</type> </optional> ) |
| <returnvalue>record</returnvalue> |
| ( <parameter>size</parameter> <type>bigint</type>, |
| <parameter>access</parameter> <type>timestamp with time zone</type>, |
| <parameter>modification</parameter> <type>timestamp with time zone</type>, |
| <parameter>change</parameter> <type>timestamp with time zone</type>, |
| <parameter>creation</parameter> <type>timestamp with time zone</type>, |
| <parameter>isdir</parameter> <type>boolean</type> ) |
| </para> |
| <para> |
| Returns a record containing the file's size, last access time stamp, |
| last modification time stamp, last file status change time stamp (Unix |
| platforms only), file creation time stamp (Windows only), and a flag |
| indicating if it is a directory. |
| </para> |
| <para> |
| This function is restricted to superusers by default, but other users |
| can be granted EXECUTE to run the function. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| </sect2> |
| |
| <sect2 id="functions-advisory-locks"> |
| <title>Advisory Lock Functions</title> |
| |
| <para> |
| The functions shown in <xref linkend="functions-advisory-locks-table"/> |
| manage advisory locks. For details about proper use of these functions, |
| see <xref linkend="advisory-locks"/>. |
| </para> |
| |
| <para> |
| All these functions are intended to be used to lock application-defined |
| resources, which can be identified either by a single 64-bit key value or |
| two 32-bit key values (note that these two key spaces do not overlap). |
| If another session already holds a conflicting lock on the same resource |
| identifier, the functions will either wait until the resource becomes |
| available, or return a <literal>false</literal> result, as appropriate for |
| the function. |
| Locks can be either shared or exclusive: a shared lock does not conflict |
| with other shared locks on the same resource, only with exclusive locks. |
| Locks can be taken at session level (so that they are held until released |
| or the session ends) or at transaction level (so that they are held until |
| the current transaction ends; there is no provision for manual release). |
| Multiple session-level lock requests stack, so that if the same resource |
| identifier is locked three times there must then be three unlock requests |
| to release the resource in advance of session end. |
| </para> |
| |
| <table id="functions-advisory-locks-table"> |
| <title>Advisory Lock Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_advisory_lock</primary> |
| </indexterm> |
| <function>pg_advisory_lock</function> ( <parameter>key</parameter> <type>bigint</type> ) |
| <returnvalue>void</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>pg_advisory_lock</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> ) |
| <returnvalue>void</returnvalue> |
| </para> |
| <para> |
| Obtains an exclusive session-level advisory lock, waiting if necessary. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_advisory_lock_shared</primary> |
| </indexterm> |
| <function>pg_advisory_lock_shared</function> ( <parameter>key</parameter> <type>bigint</type> ) |
| <returnvalue>void</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>pg_advisory_lock_shared</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> ) |
| <returnvalue>void</returnvalue> |
| </para> |
| <para> |
| Obtains a shared session-level advisory lock, waiting if necessary. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_advisory_unlock</primary> |
| </indexterm> |
| <function>pg_advisory_unlock</function> ( <parameter>key</parameter> <type>bigint</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>pg_advisory_unlock</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Releases a previously-acquired exclusive session-level advisory lock. |
| Returns <literal>true</literal> if the lock is successfully released. |
| If the lock was not held, <literal>false</literal> is returned, and in |
| addition, an SQL warning will be reported by the server. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_advisory_unlock_all</primary> |
| </indexterm> |
| <function>pg_advisory_unlock_all</function> () |
| <returnvalue>void</returnvalue> |
| </para> |
| <para> |
| Releases all session-level advisory locks held by the current session. |
| (This function is implicitly invoked at session end, even if the |
| client disconnects ungracefully.) |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_advisory_unlock_shared</primary> |
| </indexterm> |
| <function>pg_advisory_unlock_shared</function> ( <parameter>key</parameter> <type>bigint</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>pg_advisory_unlock_shared</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Releases a previously-acquired shared session-level advisory lock. |
| Returns <literal>true</literal> if the lock is successfully released. |
| If the lock was not held, <literal>false</literal> is returned, and in |
| addition, an SQL warning will be reported by the server. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_advisory_xact_lock</primary> |
| </indexterm> |
| <function>pg_advisory_xact_lock</function> ( <parameter>key</parameter> <type>bigint</type> ) |
| <returnvalue>void</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>pg_advisory_xact_lock</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> ) |
| <returnvalue>void</returnvalue> |
| </para> |
| <para> |
| Obtains an exclusive transaction-level advisory lock, waiting if |
| necessary. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_advisory_xact_lock_shared</primary> |
| </indexterm> |
| <function>pg_advisory_xact_lock_shared</function> ( <parameter>key</parameter> <type>bigint</type> ) |
| <returnvalue>void</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>pg_advisory_xact_lock_shared</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> ) |
| <returnvalue>void</returnvalue> |
| </para> |
| <para> |
| Obtains a shared transaction-level advisory lock, waiting if |
| necessary. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_try_advisory_lock</primary> |
| </indexterm> |
| <function>pg_try_advisory_lock</function> ( <parameter>key</parameter> <type>bigint</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>pg_try_advisory_lock</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Obtains an exclusive session-level advisory lock if available. |
| This will either obtain the lock immediately and |
| return <literal>true</literal>, or return <literal>false</literal> |
| without waiting if the lock cannot be acquired immediately. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_try_advisory_lock_shared</primary> |
| </indexterm> |
| <function>pg_try_advisory_lock_shared</function> ( <parameter>key</parameter> <type>bigint</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>pg_try_advisory_lock_shared</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Obtains a shared session-level advisory lock if available. |
| This will either obtain the lock immediately and |
| return <literal>true</literal>, or return <literal>false</literal> |
| without waiting if the lock cannot be acquired immediately. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_try_advisory_xact_lock</primary> |
| </indexterm> |
| <function>pg_try_advisory_xact_lock</function> ( <parameter>key</parameter> <type>bigint</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>pg_try_advisory_xact_lock</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Obtains an exclusive transaction-level advisory lock if available. |
| This will either obtain the lock immediately and |
| return <literal>true</literal>, or return <literal>false</literal> |
| without waiting if the lock cannot be acquired immediately. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_try_advisory_xact_lock_shared</primary> |
| </indexterm> |
| <function>pg_try_advisory_xact_lock_shared</function> ( <parameter>key</parameter> <type>bigint</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para role="func_signature"> |
| <function>pg_try_advisory_xact_lock_shared</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> ) |
| <returnvalue>boolean</returnvalue> |
| </para> |
| <para> |
| Obtains a shared transaction-level advisory lock if available. |
| This will either obtain the lock immediately and |
| return <literal>true</literal>, or return <literal>false</literal> |
| without waiting if the lock cannot be acquired immediately. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| </sect2> |
| |
| </sect1> |
| |
| <sect1 id="functions-trigger"> |
| <title>Trigger Functions</title> |
| |
| <para> |
| While many uses of triggers involve user-written trigger functions, |
| <productname>PostgreSQL</productname> provides a few built-in trigger |
| functions that can be used directly in user-defined triggers. These |
| are summarized in <xref linkend="builtin-triggers-table"/>. |
| (Additional built-in trigger functions exist, which implement foreign |
| key constraints and deferred index constraints. Those are not documented |
| here since users need not use them directly.) |
| </para> |
| |
| <para> |
| For more information about creating triggers, see |
| <xref linkend="sql-createtrigger"/>. |
| </para> |
| |
| <table id="builtin-triggers-table"> |
| <title>Built-In Trigger Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para> |
| <para> |
| Example Usage |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>suppress_redundant_updates_trigger</primary> |
| </indexterm> |
| <function>suppress_redundant_updates_trigger</function> ( ) |
| <returnvalue>trigger</returnvalue> |
| </para> |
| <para> |
| Suppresses do-nothing update operations. See below for details. |
| </para> |
| <para> |
| <literal>CREATE TRIGGER ... suppress_redundant_updates_trigger()</literal> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>tsvector_update_trigger</primary> |
| </indexterm> |
| <function>tsvector_update_trigger</function> ( ) |
| <returnvalue>trigger</returnvalue> |
| </para> |
| <para> |
| Automatically updates a <type>tsvector</type> column from associated |
| plain-text document column(s). The text search configuration to use |
| is specified by name as a trigger argument. See |
| <xref linkend="textsearch-update-triggers"/> for details. |
| </para> |
| <para> |
| <literal>CREATE TRIGGER ... tsvector_update_trigger(tsvcol, 'pg_catalog.swedish', title, body)</literal> |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>tsvector_update_trigger_column</primary> |
| </indexterm> |
| <function>tsvector_update_trigger_column</function> ( ) |
| <returnvalue>trigger</returnvalue> |
| </para> |
| <para> |
| Automatically updates a <type>tsvector</type> column from associated |
| plain-text document column(s). The text search configuration to use |
| is taken from a <type>regconfig</type> column of the table. See |
| <xref linkend="textsearch-update-triggers"/> for details. |
| </para> |
| <para> |
| <literal>CREATE TRIGGER ... tsvector_update_trigger_column(tsvcol, tsconfigcol, title, body)</literal> |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| The <function>suppress_redundant_updates_trigger</function> function, |
| when applied as a row-level <literal>BEFORE UPDATE</literal> trigger, |
| will prevent any update that does not actually change the data in the |
| row from taking place. This overrides the normal behavior which always |
| performs a physical row update |
| regardless of whether or not the data has changed. (This normal behavior |
| makes updates run faster, since no checking is required, and is also |
| useful in certain cases.) |
| </para> |
| |
| <para> |
| Ideally, you should avoid running updates that don't actually |
| change the data in the record. Redundant updates can cost considerable |
| unnecessary time, especially if there are lots of indexes to alter, |
| and space in dead rows that will eventually have to be vacuumed. |
| However, detecting such situations in client code is not |
| always easy, or even possible, and writing expressions to detect |
| them can be error-prone. An alternative is to use |
| <function>suppress_redundant_updates_trigger</function>, which will skip |
| updates that don't change the data. You should use this with care, |
| however. The trigger takes a small but non-trivial time for each record, |
| so if most of the records affected by updates do actually change, |
| use of this trigger will make updates run slower on average. |
| </para> |
| |
| <para> |
| The <function>suppress_redundant_updates_trigger</function> function can be |
| added to a table like this: |
| <programlisting> |
| CREATE TRIGGER z_min_update |
| BEFORE UPDATE ON tablename |
| FOR EACH ROW EXECUTE FUNCTION suppress_redundant_updates_trigger(); |
| </programlisting> |
| In most cases, you need to fire this trigger last for each row, so that |
| it does not override other triggers that might wish to alter the row. |
| Bearing in mind that triggers fire in name order, you would therefore |
| choose a trigger name that comes after the name of any other trigger |
| you might have on the table. (Hence the <quote>z</quote> prefix in the |
| example.) |
| </para> |
| </sect1> |
| |
| <sect1 id="functions-event-triggers"> |
| <title>Event Trigger Functions</title> |
| |
| <para> |
| <productname>PostgreSQL</productname> provides these helper functions |
| to retrieve information from event triggers. |
| </para> |
| |
| <para> |
| For more information about event triggers, |
| see <xref linkend="event-triggers"/>. |
| </para> |
| |
| <sect2 id="pg-event-trigger-ddl-command-end-functions"> |
| <title>Capturing Changes at Command End</title> |
| |
| <indexterm> |
| <primary>pg_event_trigger_ddl_commands</primary> |
| </indexterm> |
| |
| <synopsis> |
| <function>pg_event_trigger_ddl_commands</function> () <returnvalue>setof record</returnvalue> |
| </synopsis> |
| |
| <para> |
| <function>pg_event_trigger_ddl_commands</function> returns a list of |
| <acronym>DDL</acronym> commands executed by each user action, |
| when invoked in a function attached to a |
| <literal>ddl_command_end</literal> event trigger. If called in any other |
| context, an error is raised. |
| <function>pg_event_trigger_ddl_commands</function> returns one row for each |
| base command executed; some commands that are a single SQL sentence |
| may return more than one row. This function returns the following |
| columns: |
| |
| <informaltable> |
| <tgroup cols="3"> |
| <thead> |
| <row> |
| <entry>Name</entry> |
| <entry>Type</entry> |
| <entry>Description</entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry><literal>classid</literal></entry> |
| <entry><type>oid</type></entry> |
| <entry>OID of catalog the object belongs in</entry> |
| </row> |
| <row> |
| <entry><literal>objid</literal></entry> |
| <entry><type>oid</type></entry> |
| <entry>OID of the object itself</entry> |
| </row> |
| <row> |
| <entry><literal>objsubid</literal></entry> |
| <entry><type>integer</type></entry> |
| <entry>Sub-object ID (e.g., attribute number for a column)</entry> |
| </row> |
| <row> |
| <entry><literal>command_tag</literal></entry> |
| <entry><type>text</type></entry> |
| <entry>Command tag</entry> |
| </row> |
| <row> |
| <entry><literal>object_type</literal></entry> |
| <entry><type>text</type></entry> |
| <entry>Type of the object</entry> |
| </row> |
| <row> |
| <entry><literal>schema_name</literal></entry> |
| <entry><type>text</type></entry> |
| <entry> |
| Name of the schema the object belongs in, if any; otherwise <literal>NULL</literal>. |
| No quoting is applied. |
| </entry> |
| </row> |
| <row> |
| <entry><literal>object_identity</literal></entry> |
| <entry><type>text</type></entry> |
| <entry> |
| Text rendering of the object identity, schema-qualified. Each |
| identifier included in the identity is quoted if necessary. |
| </entry> |
| </row> |
| <row> |
| <entry><literal>in_extension</literal></entry> |
| <entry><type>boolean</type></entry> |
| <entry>True if the command is part of an extension script</entry> |
| </row> |
| <row> |
| <entry><literal>command</literal></entry> |
| <entry><type>pg_ddl_command</type></entry> |
| <entry> |
| A complete representation of the command, in internal format. |
| This cannot be output directly, but it can be passed to other |
| functions to obtain different pieces of information about the |
| command. |
| </entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </informaltable> |
| </para> |
| </sect2> |
| |
| <sect2 id="pg-event-trigger-sql-drop-functions"> |
| <title>Processing Objects Dropped by a DDL Command</title> |
| |
| <indexterm> |
| <primary>pg_event_trigger_dropped_objects</primary> |
| </indexterm> |
| |
| <synopsis> |
| <function>pg_event_trigger_dropped_objects</function> () <returnvalue>setof record</returnvalue> |
| </synopsis> |
| |
| <para> |
| <function>pg_event_trigger_dropped_objects</function> returns a list of all objects |
| dropped by the command in whose <literal>sql_drop</literal> event it is called. |
| If called in any other context, an error is raised. |
| This function returns the following columns: |
| |
| <informaltable> |
| <tgroup cols="3"> |
| <thead> |
| <row> |
| <entry>Name</entry> |
| <entry>Type</entry> |
| <entry>Description</entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry><literal>classid</literal></entry> |
| <entry><type>oid</type></entry> |
| <entry>OID of catalog the object belonged in</entry> |
| </row> |
| <row> |
| <entry><literal>objid</literal></entry> |
| <entry><type>oid</type></entry> |
| <entry>OID of the object itself</entry> |
| </row> |
| <row> |
| <entry><literal>objsubid</literal></entry> |
| <entry><type>integer</type></entry> |
| <entry>Sub-object ID (e.g., attribute number for a column)</entry> |
| </row> |
| <row> |
| <entry><literal>original</literal></entry> |
| <entry><type>boolean</type></entry> |
| <entry>True if this was one of the root object(s) of the deletion</entry> |
| </row> |
| <row> |
| <entry><literal>normal</literal></entry> |
| <entry><type>boolean</type></entry> |
| <entry> |
| True if there was a normal dependency relationship |
| in the dependency graph leading to this object |
| </entry> |
| </row> |
| <row> |
| <entry><literal>is_temporary</literal></entry> |
| <entry><type>boolean</type></entry> |
| <entry> |
| True if this was a temporary object |
| </entry> |
| </row> |
| <row> |
| <entry><literal>object_type</literal></entry> |
| <entry><type>text</type></entry> |
| <entry>Type of the object</entry> |
| </row> |
| <row> |
| <entry><literal>schema_name</literal></entry> |
| <entry><type>text</type></entry> |
| <entry> |
| Name of the schema the object belonged in, if any; otherwise <literal>NULL</literal>. |
| No quoting is applied. |
| </entry> |
| </row> |
| <row> |
| <entry><literal>object_name</literal></entry> |
| <entry><type>text</type></entry> |
| <entry> |
| Name of the object, if the combination of schema and name can be |
| used as a unique identifier for the object; otherwise <literal>NULL</literal>. |
| No quoting is applied, and name is never schema-qualified. |
| </entry> |
| </row> |
| <row> |
| <entry><literal>object_identity</literal></entry> |
| <entry><type>text</type></entry> |
| <entry> |
| Text rendering of the object identity, schema-qualified. Each |
| identifier included in the identity is quoted if necessary. |
| </entry> |
| </row> |
| <row> |
| <entry><literal>address_names</literal></entry> |
| <entry><type>text[]</type></entry> |
| <entry> |
| An array that, together with <literal>object_type</literal> and |
| <literal>address_args</literal>, can be used by |
| the <function>pg_get_object_address</function> function to |
| recreate the object address in a remote server containing an |
| identically named object of the same kind. |
| </entry> |
| </row> |
| <row> |
| <entry><literal>address_args</literal></entry> |
| <entry><type>text[]</type></entry> |
| <entry> |
| Complement for <literal>address_names</literal> |
| </entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </informaltable> |
| </para> |
| |
| <para> |
| The <function>pg_event_trigger_dropped_objects</function> function can be used |
| in an event trigger like this: |
| <programlisting> |
| CREATE FUNCTION test_event_trigger_for_drops() |
| RETURNS event_trigger LANGUAGE plpgsql AS $$ |
| DECLARE |
| obj record; |
| BEGIN |
| FOR obj IN SELECT * FROM pg_event_trigger_dropped_objects() |
| LOOP |
| RAISE NOTICE '% dropped object: % %.% %', |
| tg_tag, |
| obj.object_type, |
| obj.schema_name, |
| obj.object_name, |
| obj.object_identity; |
| END LOOP; |
| END; |
| $$; |
| CREATE EVENT TRIGGER test_event_trigger_for_drops |
| ON sql_drop |
| EXECUTE FUNCTION test_event_trigger_for_drops(); |
| </programlisting> |
| </para> |
| </sect2> |
| |
| <sect2 id="pg-event-trigger-table-rewrite-functions"> |
| <title>Handling a Table Rewrite Event</title> |
| |
| <para> |
| The functions shown in |
| <xref linkend="functions-event-trigger-table-rewrite"/> |
| provide information about a table for which a |
| <literal>table_rewrite</literal> event has just been called. |
| If called in any other context, an error is raised. |
| </para> |
| |
| <table id="functions-event-trigger-table-rewrite"> |
| <title>Table Rewrite Information Functions</title> |
| <tgroup cols="1"> |
| <thead> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| Function |
| </para> |
| <para> |
| Description |
| </para></entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_event_trigger_table_rewrite_oid</primary> |
| </indexterm> |
| <function>pg_event_trigger_table_rewrite_oid</function> () |
| <returnvalue>oid</returnvalue> |
| </para> |
| <para> |
| Returns the OID of the table about to be rewritten. |
| </para></entry> |
| </row> |
| |
| <row> |
| <entry role="func_table_entry"><para role="func_signature"> |
| <indexterm> |
| <primary>pg_event_trigger_table_rewrite_reason</primary> |
| </indexterm> |
| <function>pg_event_trigger_table_rewrite_reason</function> () |
| <returnvalue>integer</returnvalue> |
| </para> |
| <para> |
| Returns a code explaining the reason(s) for rewriting. The exact |
| meaning of the codes is release dependent. |
| </para></entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </table> |
| |
| <para> |
| These functions can be used in an event trigger like this: |
| <programlisting> |
| CREATE FUNCTION test_event_trigger_table_rewrite_oid() |
| RETURNS event_trigger |
| LANGUAGE plpgsql AS |
| $$ |
| BEGIN |
| RAISE NOTICE 'rewriting table % for reason %', |
| pg_event_trigger_table_rewrite_oid()::regclass, |
| pg_event_trigger_table_rewrite_reason(); |
| END; |
| $$; |
| |
| CREATE EVENT TRIGGER test_table_rewrite_oid |
| ON table_rewrite |
| EXECUTE FUNCTION test_event_trigger_table_rewrite_oid(); |
| </programlisting> |
| </para> |
| </sect2> |
| </sect1> |
| |
| <sect1 id="functions-statistics"> |
| <title>Statistics Information Functions</title> |
| |
| <indexterm zone="functions-statistics"> |
| <primary>function</primary> |
| <secondary>statistics</secondary> |
| </indexterm> |
| |
| <para> |
| <productname>PostgreSQL</productname> provides a function to inspect complex |
| statistics defined using the <command>CREATE STATISTICS</command> command. |
| </para> |
| |
| <sect2 id="functions-statistics-mcv"> |
| <title>Inspecting MCV Lists</title> |
| |
| <indexterm> |
| <primary>pg_mcv_list_items</primary> |
| </indexterm> |
| |
| <synopsis> |
| <function>pg_mcv_list_items</function> ( <type>pg_mcv_list</type> ) <returnvalue>setof record</returnvalue> |
| </synopsis> |
| |
| <para> |
| <function>pg_mcv_list_items</function> returns a set of records describing |
| all items stored in a multi-column <acronym>MCV</acronym> list. It |
| returns the following columns: |
| |
| <informaltable> |
| <tgroup cols="3"> |
| <thead> |
| <row> |
| <entry>Name</entry> |
| <entry>Type</entry> |
| <entry>Description</entry> |
| </row> |
| </thead> |
| |
| <tbody> |
| <row> |
| <entry><literal>index</literal></entry> |
| <entry><type>integer</type></entry> |
| <entry>index of the item in the <acronym>MCV</acronym> list</entry> |
| </row> |
| <row> |
| <entry><literal>values</literal></entry> |
| <entry><type>text[]</type></entry> |
| <entry>values stored in the MCV item</entry> |
| </row> |
| <row> |
| <entry><literal>nulls</literal></entry> |
| <entry><type>boolean[]</type></entry> |
| <entry>flags identifying <literal>NULL</literal> values</entry> |
| </row> |
| <row> |
| <entry><literal>frequency</literal></entry> |
| <entry><type>double precision</type></entry> |
| <entry>frequency of this <acronym>MCV</acronym> item</entry> |
| </row> |
| <row> |
| <entry><literal>base_frequency</literal></entry> |
| <entry><type>double precision</type></entry> |
| <entry>base frequency of this <acronym>MCV</acronym> item</entry> |
| </row> |
| </tbody> |
| </tgroup> |
| </informaltable> |
| </para> |
| |
| <para> |
| The <function>pg_mcv_list_items</function> function can be used like this: |
| |
| <programlisting> |
| SELECT m.* FROM pg_statistic_ext join pg_statistic_ext_data on (oid = stxoid), |
| pg_mcv_list_items(stxdmcv) m WHERE stxname = 'stts'; |
| </programlisting> |
| |
| Values of the <type>pg_mcv_list</type> type can be obtained only from the |
| <structname>pg_statistic_ext_data</structname>.<structfield>stxdmcv</structfield> |
| column. |
| </para> |
| </sect2> |
| |
| </sect1> |
| |
| </chapter> |