mirror of
https://github.com/postgres/postgres.git
synced 2025-07-30 11:03:19 +03:00
Generated columns
This is an SQL-standard feature that allows creating columns that are computed from expressions rather than assigned, similar to a view or materialized view but on a column basis. This implements one kind of generated column: stored (computed on write). Another kind, virtual (computed on read), is planned for the future, and some room is left for it. Reviewed-by: Michael Paquier <michael@paquier.xyz> Reviewed-by: Pavel Stehule <pavel.stehule@gmail.com> Discussion: https://www.postgresql.org/message-id/flat/b151f851-4019-bdb1-699e-ebab07d2f40a@2ndquadrant.com
This commit is contained in:
@ -1129,9 +1129,11 @@
|
||||
<entry><type>bool</type></entry>
|
||||
<entry></entry>
|
||||
<entry>
|
||||
This column has a default value, in which case there will be a
|
||||
corresponding entry in the <structname>pg_attrdef</structname>
|
||||
catalog that actually defines the value.
|
||||
This column has a default expression or generation expression, in which
|
||||
case there will be a corresponding entry in the
|
||||
<structname>pg_attrdef</structname> catalog that actually defines the
|
||||
expression. (Check <structfield>attgenerated</structfield> to
|
||||
determine whether this is a default or a generation expression.)
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
@ -1159,6 +1161,17 @@
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structfield>attgenerated</structfield></entry>
|
||||
<entry><type>char</type></entry>
|
||||
<entry></entry>
|
||||
<entry>
|
||||
If a zero byte (<literal>''</literal>), then not a generated column.
|
||||
Otherwise, <literal>s</literal> = stored. (Other values might be added
|
||||
in the future.)
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structfield>attisdropped</structfield></entry>
|
||||
<entry><type>bool</type></entry>
|
||||
|
@ -233,6 +233,124 @@ CREATE TABLE products (
|
||||
</para>
|
||||
</sect1>
|
||||
|
||||
<sect1 id="ddl-generated-columns">
|
||||
<title>Generated Columns</title>
|
||||
|
||||
<indexterm zone="ddl-generated-columns">
|
||||
<primary>generated column</primary>
|
||||
</indexterm>
|
||||
|
||||
<para>
|
||||
A generated column is a special column that is always computed from other
|
||||
columns. Thus, it is for columns what a view is for tables. There are two
|
||||
kinds of generated columns: stored and virtual. A stored generated column
|
||||
is computed when it is written (inserted or updated) and occupies storage
|
||||
as if it were a normal column. A virtual generated column occupies no
|
||||
storage and is computed when it is read. Thus, a virtual generated column
|
||||
is similar to a view and a stored generated column is similar to a
|
||||
materialized view (except that it is always updated automatically).
|
||||
PostgreSQL currently implements only stored generated columns.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
To create a generated column, use the <literal>GENERATED ALWAYS
|
||||
AS</literal> clause in <command>CREATE TABLE</command>, for example:
|
||||
<programlisting>
|
||||
CREATE TABLE people (
|
||||
...,
|
||||
height_cm numeric,
|
||||
height_in numeric <emphasis>GENERATED ALWAYS AS (height_cm * 2.54) STORED</emphasis>
|
||||
);
|
||||
</programlisting>
|
||||
The keyword <literal>STORED</literal> must be specified to choose the
|
||||
stored kind of generated column. See <xref linkend="sql-createtable"/> for
|
||||
more details.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
A generated column cannot be written to directly. In
|
||||
<command>INSERT</command> or <command>UPDATE</command> commands, a value
|
||||
cannot be specified for a generated column, but the keyword
|
||||
<literal>DEFAULT</literal> may be specified.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
Consider the differences between a column with a default and a generated
|
||||
column. The column default is evaluated once when the row is first
|
||||
inserted if no other value was provided; a generated column is updated
|
||||
whenever the row changes and cannot be overridden. A column default may
|
||||
not refer to other columns of the table; a generation expression would
|
||||
normally do so. A column default can use volatile functions, for example
|
||||
<literal>random()</literal> or functions referring to the current time;
|
||||
this is not allowed for generated columns.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
Several restrictions apply to the definition of generated columns and
|
||||
tables involving generated columns:
|
||||
|
||||
<itemizedlist>
|
||||
<listitem>
|
||||
<para>
|
||||
The generation expression can only use immutable functions and cannot
|
||||
use subqueries or reference anything other than the current row in any
|
||||
way.
|
||||
</para>
|
||||
</listitem>
|
||||
<listitem>
|
||||
<para>
|
||||
A generation expression cannot reference another generated column.
|
||||
</para>
|
||||
</listitem>
|
||||
<listitem>
|
||||
<para>
|
||||
A generation expression cannot reference a system column, except
|
||||
<varname>tableoid</varname>.
|
||||
</para>
|
||||
</listitem>
|
||||
<listitem>
|
||||
<para>
|
||||
A generated column cannot have a column default or an identity definition.
|
||||
</para>
|
||||
</listitem>
|
||||
<listitem>
|
||||
<para>
|
||||
A generated column cannot be part of a partition key.
|
||||
</para>
|
||||
</listitem>
|
||||
<listitem>
|
||||
<para>
|
||||
Foreign tables can have generated columns. See <xref
|
||||
linkend="sql-createforeigntable"/> for details.
|
||||
</para>
|
||||
</listitem>
|
||||
</itemizedlist>
|
||||
</para>
|
||||
|
||||
<para>
|
||||
Additional considerations apply to the use of generated columns.
|
||||
<itemizedlist>
|
||||
<listitem>
|
||||
<para>
|
||||
Generated columns maintain access privileges separately from their
|
||||
underlying base columns. So, it is possible to arrange it so that a
|
||||
particular role can read from a generated column but not from the
|
||||
underlying base columns.
|
||||
</para>
|
||||
</listitem>
|
||||
<listitem>
|
||||
<para>
|
||||
Generated columns are, conceptually, updated after
|
||||
<literal>BEFORE</literal> triggers have run. Therefore, changes made to
|
||||
base columns in a <literal>BEFORE</literal> trigger will be reflected in
|
||||
generated columns. But conversely, it is not allowed to access
|
||||
generated columns in <literal>BEFORE</literal> triggers.
|
||||
</para>
|
||||
</listitem>
|
||||
</itemizedlist>
|
||||
</para>
|
||||
</sect1>
|
||||
|
||||
<sect1 id="ddl-constraints">
|
||||
<title>Constraints</title>
|
||||
|
||||
|
@ -952,6 +952,62 @@
|
||||
</table>
|
||||
</sect1>
|
||||
|
||||
<sect1 id="infoschema-column-column-usage">
|
||||
<title><literal>column_column_usage</literal></title>
|
||||
|
||||
<para>
|
||||
The view <literal>column_column_usage</literal> identifies all generated
|
||||
columns that depend on another base column in the same table. Only tables
|
||||
owned by a currently enabled role are included.
|
||||
</para>
|
||||
|
||||
<table>
|
||||
<title><literal>column_column_usage</literal> Columns</title>
|
||||
|
||||
<tgroup cols="3">
|
||||
<thead>
|
||||
<row>
|
||||
<entry>Name</entry>
|
||||
<entry>Data Type</entry>
|
||||
<entry>Description</entry>
|
||||
</row>
|
||||
</thead>
|
||||
|
||||
<tbody>
|
||||
<row>
|
||||
<entry><literal>table_catalog</literal></entry>
|
||||
<entry><type>sql_identifier</type></entry>
|
||||
<entry>Name of the database containing the table (always the current database)</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><literal>table_schema</literal></entry>
|
||||
<entry><type>sql_identifier</type></entry>
|
||||
<entry>Name of the schema containing the table</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><literal>table_name</literal></entry>
|
||||
<entry><type>sql_identifier</type></entry>
|
||||
<entry>Name of the table</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><literal>column_name</literal></entry>
|
||||
<entry><type>sql_identifier</type></entry>
|
||||
<entry>Name of the base column that a generated column depends on</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><literal>dependent_column</literal></entry>
|
||||
<entry><type>sql_identifier</type></entry>
|
||||
<entry>Name of the generated column</entry>
|
||||
</row>
|
||||
</tbody>
|
||||
</tgroup>
|
||||
</table>
|
||||
</sect1>
|
||||
|
||||
<sect1 id="infoschema-column-domain-usage">
|
||||
<title><literal>column_domain_usage</literal></title>
|
||||
|
||||
@ -1648,13 +1704,19 @@
|
||||
<row>
|
||||
<entry><literal>is_generated</literal></entry>
|
||||
<entry><type>character_data</type></entry>
|
||||
<entry>Applies to a feature not available in <productname>PostgreSQL</productname></entry>
|
||||
<entry>
|
||||
If the column is a generated column, then <literal>ALWAYS</literal>,
|
||||
else <literal>NEVER</literal>.
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><literal>generation_expression</literal></entry>
|
||||
<entry><type>character_data</type></entry>
|
||||
<entry>Applies to a feature not available in <productname>PostgreSQL</productname></entry>
|
||||
<entry>
|
||||
If the column is a generated column, then the generation expression,
|
||||
else null.
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
|
@ -6450,7 +6450,7 @@ Relation
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
</variablelist>
|
||||
Next, the following message part appears for each column:
|
||||
Next, the following message part appears for each column (except generated columns):
|
||||
<variablelist>
|
||||
<varlistentry>
|
||||
<term>
|
||||
@ -6875,7 +6875,7 @@ TupleData
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
</variablelist>
|
||||
Next, one of the following submessages appears for each column:
|
||||
Next, one of the following submessages appears for each column (except generated columns):
|
||||
<variablelist>
|
||||
<varlistentry>
|
||||
<term>
|
||||
|
@ -103,7 +103,8 @@ COPY { <replaceable class="parameter">table_name</replaceable> [ ( <replaceable
|
||||
<listitem>
|
||||
<para>
|
||||
An optional list of columns to be copied. If no column list is
|
||||
specified, all columns of the table will be copied.
|
||||
specified, all columns of the table except generated columns will be
|
||||
copied.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
@ -42,7 +42,8 @@ CREATE FOREIGN TABLE [ IF NOT EXISTS ] <replaceable class="parameter">table_name
|
||||
{ NOT NULL |
|
||||
NULL |
|
||||
CHECK ( <replaceable class="parameter">expression</replaceable> ) [ NO INHERIT ] |
|
||||
DEFAULT <replaceable>default_expr</replaceable> }
|
||||
DEFAULT <replaceable>default_expr</replaceable> |
|
||||
GENERATED ALWAYS AS ( <replaceable>generation_expr</replaceable> ) STORED }
|
||||
|
||||
<phrase>and <replaceable class="parameter">table_constraint</replaceable> is:</phrase>
|
||||
|
||||
@ -258,6 +259,30 @@ CHECK ( <replaceable class="parameter">expression</replaceable> ) [ NO INHERIT ]
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>GENERATED ALWAYS AS ( <replaceable>generation_expr</replaceable> ) STORED</literal><indexterm><primary>generated column</primary></indexterm></term>
|
||||
<listitem>
|
||||
<para>
|
||||
This clause creates the column as a <firstterm>generated
|
||||
column</firstterm>. The column cannot be written to, and when read it
|
||||
will be computed from the specified expression.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
The keyword <literal>STORED</literal> is required to signify that the
|
||||
column will be computed on write. (The computed value will be presented
|
||||
to the foreign-data wrapper for storage and must be returned on
|
||||
reading.)
|
||||
</para>
|
||||
|
||||
<para>
|
||||
The generation expression can refer to other columns in the table, but
|
||||
not other generated columns. Any functions and operators used must be
|
||||
immutable. References to other tables are not allowed.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><replaceable class="parameter">server_name</replaceable></term>
|
||||
<listitem>
|
||||
|
@ -62,6 +62,7 @@ CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXI
|
||||
NULL |
|
||||
CHECK ( <replaceable class="parameter">expression</replaceable> ) [ NO INHERIT ] |
|
||||
DEFAULT <replaceable>default_expr</replaceable> |
|
||||
GENERATED ALWAYS AS ( <replaceable>generation_expr</replaceable> ) STORED |
|
||||
GENERATED { ALWAYS | BY DEFAULT } AS IDENTITY [ ( <replaceable>sequence_options</replaceable> ) ] |
|
||||
UNIQUE <replaceable class="parameter">index_parameters</replaceable> |
|
||||
PRIMARY KEY <replaceable class="parameter">index_parameters</replaceable> |
|
||||
@ -83,7 +84,7 @@ class="parameter">referential_action</replaceable> ] [ ON UPDATE <replaceable cl
|
||||
|
||||
<phrase>and <replaceable class="parameter">like_option</replaceable> is:</phrase>
|
||||
|
||||
{ INCLUDING | EXCLUDING } { COMMENTS | CONSTRAINTS | DEFAULTS | IDENTITY | INDEXES | STATISTICS | STORAGE | ALL }
|
||||
{ INCLUDING | EXCLUDING } { COMMENTS | CONSTRAINTS | DEFAULTS | GENERATED | IDENTITY | INDEXES | STATISTICS | STORAGE | ALL }
|
||||
|
||||
<phrase>and <replaceable class="parameter">partition_bound_spec</replaceable> is:</phrase>
|
||||
|
||||
@ -627,6 +628,16 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>INCLUDING GENERATED</literal></term>
|
||||
<listitem>
|
||||
<para>
|
||||
Any generation expressions of copied column definitions will be
|
||||
copied. By default, new columns will be regular base columns.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>INCLUDING IDENTITY</literal></term>
|
||||
<listitem>
|
||||
@ -797,6 +808,28 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>GENERATED ALWAYS AS ( <replaceable>generation_expr</replaceable> ) STORED</literal><indexterm><primary>generated column</primary></indexterm></term>
|
||||
<listitem>
|
||||
<para>
|
||||
This clause creates the column as a <firstterm>generated
|
||||
column</firstterm>. The column cannot be written to, and when read it
|
||||
will be computed from the specified expression.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
The keyword <literal>STORED</literal> is required to signify that the
|
||||
column will be computed on write and will be stored on disk. default.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
The generation expression can refer to other columns in the table, but
|
||||
not other generated columns. Any functions and operators used must be
|
||||
immutable. References to other tables are not allowed.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>GENERATED { ALWAYS | BY DEFAULT } AS IDENTITY [ ( <replaceable>sequence_options</replaceable> ) ]</literal></term>
|
||||
<listitem>
|
||||
@ -2028,6 +2061,16 @@ CREATE TABLE cities_partdef
|
||||
</para>
|
||||
</refsect2>
|
||||
|
||||
<refsect2>
|
||||
<title>Generated Columns</title>
|
||||
|
||||
<para>
|
||||
The option <literal>STORED</literal> is not standard but is also used by
|
||||
other SQL implementations. The SQL standard does not specify the storage
|
||||
of generated columns.
|
||||
</para>
|
||||
</refsect2>
|
||||
|
||||
<refsect2>
|
||||
<title><literal>LIKE</literal> Clause</title>
|
||||
|
||||
|
@ -261,7 +261,9 @@ CREATE [ CONSTRAINT ] TRIGGER <replaceable class="parameter">name</replaceable>
|
||||
UPDATE OF <replaceable>column_name1</replaceable> [, <replaceable>column_name2</replaceable> ... ]
|
||||
</synopsis>
|
||||
The trigger will only fire if at least one of the listed columns
|
||||
is mentioned as a target of the <command>UPDATE</command> command.
|
||||
is mentioned as a target of the <command>UPDATE</command> command
|
||||
or if one of the listed columns is a generated column that depends on a
|
||||
column that is the target of the <command>UPDATE</command>.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
|
@ -620,15 +620,17 @@ CREATE INDEX pgweb_idx ON pgweb USING GIN (to_tsvector('english', title || ' ' |
|
||||
|
||||
<para>
|
||||
Another approach is to create a separate <type>tsvector</type> column
|
||||
to hold the output of <function>to_tsvector</function>. This example is a
|
||||
to hold the output of <function>to_tsvector</function>. To keep this
|
||||
column automatically up to date with its source data, use a stored
|
||||
generated column. This example is a
|
||||
concatenation of <literal>title</literal> and <literal>body</literal>,
|
||||
using <function>coalesce</function> to ensure that one field will still be
|
||||
indexed when the other is <literal>NULL</literal>:
|
||||
|
||||
<programlisting>
|
||||
ALTER TABLE pgweb ADD COLUMN textsearchable_index_col tsvector;
|
||||
UPDATE pgweb SET textsearchable_index_col =
|
||||
to_tsvector('english', coalesce(title,'') || ' ' || coalesce(body,''));
|
||||
ALTER TABLE pgweb
|
||||
ADD COLUMN textsearchable_index_col tsvector
|
||||
GENERATED ALWAYS AS (to_tsvector('english', coalesce(title, '') || ' ' || coalesce(body, ''))) STORED;
|
||||
</programlisting>
|
||||
|
||||
Then we create a <acronym>GIN</acronym> index to speed up the search:
|
||||
@ -648,14 +650,6 @@ LIMIT 10;
|
||||
</programlisting>
|
||||
</para>
|
||||
|
||||
<para>
|
||||
When using a separate column to store the <type>tsvector</type>
|
||||
representation,
|
||||
it is necessary to create a trigger to keep the <type>tsvector</type>
|
||||
column current anytime <literal>title</literal> or <literal>body</literal> changes.
|
||||
<xref linkend="textsearch-update-triggers"/> explains how to do that.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
One advantage of the separate-column approach over an expression index
|
||||
is that it is not necessary to explicitly specify the text search
|
||||
@ -1857,6 +1851,14 @@ SELECT ts_rewrite('a & b'::tsquery,
|
||||
<secondary>for updating a derived tsvector column</secondary>
|
||||
</indexterm>
|
||||
|
||||
<note>
|
||||
<para>
|
||||
The method described in this section has been obsoleted by the use of
|
||||
stored generated columns, as described in <xref
|
||||
linkend="textsearch-tables-index"/>.
|
||||
</para>
|
||||
</note>
|
||||
|
||||
<para>
|
||||
When using a separate column to store the <type>tsvector</type> representation
|
||||
of your documents, it is necessary to create a trigger to update the
|
||||
|
@ -243,6 +243,24 @@
|
||||
operation, and so they can return <symbol>NULL</symbol>.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
Some considerations apply for generated
|
||||
columns.<indexterm><primary>generated column</primary><secondary>in
|
||||
triggers</secondary></indexterm> Stored generated columns are computed after
|
||||
<literal>BEFORE</literal> triggers and before <literal>AFTER</literal>
|
||||
triggers. Therefore, the generated value can be inspected in
|
||||
<literal>AFTER</literal> triggers. In <literal>BEFORE</literal> triggers,
|
||||
the <literal>OLD</literal> row contains the old generated value, as one
|
||||
would expect, but the <literal>NEW</literal> row does not yet contain the
|
||||
new generated value and should not be accessed. In the C language
|
||||
interface, the content of the column is undefined at this point; a
|
||||
higher-level programming language should prevent access to a stored
|
||||
generated column in the <literal>NEW</literal> row in a
|
||||
<literal>BEFORE</literal> trigger. Changes to the value of a generated
|
||||
column in a <literal>BEFORE</literal> trigger are ignored and will be
|
||||
overwritten.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
If more than one trigger is defined for the same event on the same
|
||||
relation, the triggers will be fired in alphabetical order by
|
||||
|
Reference in New Issue
Block a user