Skip to content

Commit

Permalink
Browse files Browse the repository at this point in the history
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
  • Loading branch information
petere committed Mar 30, 2019
1 parent 6b8b536 commit fc22b66
Show file tree
Hide file tree
Showing 84 changed files with 3,065 additions and 155 deletions.
25 changes: 25 additions & 0 deletions contrib/postgres_fdw/expected/postgres_fdw.out
Expand Up @@ -6431,6 +6431,31 @@ select * from rem1;
11 | bye remote
(4 rows)

-- ===================================================================
-- test generated columns
-- ===================================================================
create table gloc1 (a int, b int);
alter table gloc1 set (autovacuum_enabled = 'false');
create foreign table grem1 (
a int,
b int generated always as (a * 2) stored)
server loopback options(table_name 'gloc1');
insert into grem1 (a) values (1), (2);
update grem1 set a = 22 where a = 2;
select * from gloc1;
a | b
----+----
1 | 2
22 | 44
(2 rows)

select * from grem1;
a | b
----+----
1 | 2
22 | 44
(2 rows)

-- ===================================================================
-- test local triggers
-- ===================================================================
Expand Down
3 changes: 2 additions & 1 deletion contrib/postgres_fdw/postgres_fdw.c
Expand Up @@ -1644,9 +1644,10 @@ postgresPlanForeignModify(PlannerInfo *root,
else if (operation == CMD_UPDATE)
{
int col;
Bitmapset *allUpdatedCols = bms_union(rte->updatedCols, rte->extraUpdatedCols);

col = -1;
while ((col = bms_next_member(rte->updatedCols, col)) >= 0)
while ((col = bms_next_member(allUpdatedCols, col)) >= 0)
{
/* bit numbers are offset by FirstLowInvalidHeapAttributeNumber */
AttrNumber attno = col + FirstLowInvalidHeapAttributeNumber;
Expand Down
14 changes: 14 additions & 0 deletions contrib/postgres_fdw/sql/postgres_fdw.sql
Expand Up @@ -1363,6 +1363,20 @@ insert into rem1(f2) values('bye remote');
select * from loc1;
select * from rem1;

-- ===================================================================
-- test generated columns
-- ===================================================================
create table gloc1 (a int, b int);
alter table gloc1 set (autovacuum_enabled = 'false');
create foreign table grem1 (
a int,
b int generated always as (a * 2) stored)
server loopback options(table_name 'gloc1');
insert into grem1 (a) values (1), (2);
update grem1 set a = 22 where a = 2;
select * from gloc1;
select * from grem1;

-- ===================================================================
-- test local triggers
-- ===================================================================
Expand Down
19 changes: 16 additions & 3 deletions doc/src/sgml/catalogs.sgml
Expand Up @@ -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>

Expand Down Expand Up @@ -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>
Expand Down
118 changes: 118 additions & 0 deletions doc/src/sgml/ddl.sgml
Expand Up @@ -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>

This comment has been minimized.

Copy link
@rowland

rowland Apr 3, 2019

Formula for cm-to-in conversion is height_cm / 2.54, not height_cm * 2.54.

);
</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>

Expand Down
66 changes: 64 additions & 2 deletions doc/src/sgml/information_schema.sgml
Expand Up @@ -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>

Expand Down Expand Up @@ -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>
Expand Down
4 changes: 2 additions & 2 deletions doc/src/sgml/protocol.sgml
Expand Up @@ -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>
Expand Down Expand Up @@ -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>
Expand Down
3 changes: 2 additions & 1 deletion doc/src/sgml/ref/copy.sgml
Expand Up @@ -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>
Expand Down
27 changes: 26 additions & 1 deletion doc/src/sgml/ref/create_foreign_table.sgml
Expand Up @@ -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>

Expand Down Expand Up @@ -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>
Expand Down

0 comments on commit fc22b66

Please sign in to comment.