mirror of
https://git.postgresql.org/git/postgresql.git
synced 2025-03-19 20:00:51 +08:00
Virtual generated columns
This adds a new variant of generated columns that are computed on read (like a view, unlike the existing stored generated columns, which are computed on write, like a materialized view). The syntax for the column definition is ... GENERATED ALWAYS AS (...) VIRTUAL and VIRTUAL is also optional. VIRTUAL is the default rather than STORED to match various other SQL products. (The SQL standard makes no specification about this, but it also doesn't know about VIRTUAL or STORED.) (Also, virtual views are the default, rather than materialized views.) Virtual generated columns are stored in tuples as null values. (A very early version of this patch had the ambition to not store them at all. But so much stuff breaks or gets confused if you have tuples where a column in the middle is completely missing. This is a compromise, and it still saves space over being forced to use stored generated columns. If we ever find a way to improve this, a bit of pg_upgrade cleverness could allow for upgrades to a newer scheme.) The capabilities and restrictions of virtual generated columns are mostly the same as for stored generated columns. In some cases, this patch keeps virtual generated columns more restricted than they might technically need to be, to keep the two kinds consistent. Some of that could maybe be relaxed later after separate careful considerations. Some functionality that is currently not supported, but could possibly be added as incremental features, some easier than others: - index on or using a virtual column - hence also no unique constraints on virtual columns - extended statistics on virtual columns - foreign-key constraints on virtual columns - not-null constraints on virtual columns (check constraints are supported) - ALTER TABLE / DROP EXPRESSION - virtual column cannot have domain type - virtual columns are not supported in logical replication The tests in generated_virtual.sql have been copied over from generated_stored.sql with the keyword replaced. This way we can make sure the behavior is mostly aligned, and the differences can be visible. Some tests for currently not supported features are currently commented out. Reviewed-by: Jian He <jian.universality@gmail.com> Reviewed-by: Dean Rasheed <dean.a.rasheed@gmail.com> Tested-by: Shlok Kyal <shlok.kyal.oss@gmail.com> Discussion: https://www.postgresql.org/message-id/flat/a368248e-69e4-40be-9c07-6c3b5880b0a6@eisentraut.org
This commit is contained in:
parent
cbc127917e
commit
83ea6c5402
contrib
doc/src/sgml
src
backend
access
catalog
commands
executor
parser
replication/pgoutput
rewrite
utils/cache
bin
include
access
catalog
executor
nodes
parser
rewrite
pl
plperl
plpython
tcl
test
@ -208,6 +208,43 @@ select tuple_data_split('test8'::regclass, t_data, t_infomask, t_infomask2, t_bi
|
||||
(1 row)
|
||||
|
||||
drop table test8;
|
||||
-- check storage of generated columns
|
||||
-- stored
|
||||
create table test9s (a int not null, b int generated always as (a * 2) stored);
|
||||
insert into test9s values (131584);
|
||||
select raw_flags, t_bits, t_data
|
||||
from heap_page_items(get_raw_page('test9s', 0)), lateral heap_tuple_infomask_flags(t_infomask, t_infomask2);
|
||||
raw_flags | t_bits | t_data
|
||||
---------------------+--------+--------------------
|
||||
{HEAP_XMAX_INVALID} | | \x0002020000040400
|
||||
(1 row)
|
||||
|
||||
select tuple_data_split('test9s'::regclass, t_data, t_infomask, t_infomask2, t_bits)
|
||||
from heap_page_items(get_raw_page('test9s', 0));
|
||||
tuple_data_split
|
||||
-------------------------------
|
||||
{"\\x00020200","\\x00040400"}
|
||||
(1 row)
|
||||
|
||||
drop table test9s;
|
||||
-- virtual
|
||||
create table test9v (a int not null, b int generated always as (a * 2) virtual);
|
||||
insert into test9v values (131584);
|
||||
select raw_flags, t_bits, t_data
|
||||
from heap_page_items(get_raw_page('test9v', 0)), lateral heap_tuple_infomask_flags(t_infomask, t_infomask2);
|
||||
raw_flags | t_bits | t_data
|
||||
----------------------------------+----------+------------
|
||||
{HEAP_HASNULL,HEAP_XMAX_INVALID} | 10000000 | \x00020200
|
||||
(1 row)
|
||||
|
||||
select tuple_data_split('test9v'::regclass, t_data, t_infomask, t_infomask2, t_bits)
|
||||
from heap_page_items(get_raw_page('test9v', 0));
|
||||
tuple_data_split
|
||||
----------------------
|
||||
{"\\x00020200",NULL}
|
||||
(1 row)
|
||||
|
||||
drop table test9v;
|
||||
-- Failure with incorrect page size
|
||||
-- Suppress the DETAIL message, to allow the tests to work across various
|
||||
-- page sizes.
|
||||
|
@ -84,6 +84,25 @@ select tuple_data_split('test8'::regclass, t_data, t_infomask, t_infomask2, t_bi
|
||||
from heap_page_items(get_raw_page('test8', 0));
|
||||
drop table test8;
|
||||
|
||||
-- check storage of generated columns
|
||||
-- stored
|
||||
create table test9s (a int not null, b int generated always as (a * 2) stored);
|
||||
insert into test9s values (131584);
|
||||
select raw_flags, t_bits, t_data
|
||||
from heap_page_items(get_raw_page('test9s', 0)), lateral heap_tuple_infomask_flags(t_infomask, t_infomask2);
|
||||
select tuple_data_split('test9s'::regclass, t_data, t_infomask, t_infomask2, t_bits)
|
||||
from heap_page_items(get_raw_page('test9s', 0));
|
||||
drop table test9s;
|
||||
|
||||
-- virtual
|
||||
create table test9v (a int not null, b int generated always as (a * 2) virtual);
|
||||
insert into test9v values (131584);
|
||||
select raw_flags, t_bits, t_data
|
||||
from heap_page_items(get_raw_page('test9v', 0)), lateral heap_tuple_infomask_flags(t_infomask, t_infomask2);
|
||||
select tuple_data_split('test9v'::regclass, t_data, t_infomask, t_infomask2, t_bits)
|
||||
from heap_page_items(get_raw_page('test9v', 0));
|
||||
drop table test9v;
|
||||
|
||||
-- Failure with incorrect page size
|
||||
-- Suppress the DETAIL message, to allow the tests to work across various
|
||||
-- page sizes.
|
||||
|
@ -7395,65 +7395,68 @@ select * from rem1;
|
||||
-- ===================================================================
|
||||
create table gloc1 (
|
||||
a int,
|
||||
b int generated always as (a * 2) stored);
|
||||
b int generated always as (a * 2) stored,
|
||||
c 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');
|
||||
b int generated always as (a * 2) stored,
|
||||
c int generated always as (a * 3) virtual
|
||||
) server loopback options(table_name 'gloc1');
|
||||
explain (verbose, costs off)
|
||||
insert into grem1 (a) values (1), (2);
|
||||
QUERY PLAN
|
||||
-------------------------------------------------------------------
|
||||
QUERY PLAN
|
||||
-------------------------------------------------------------------------------
|
||||
Insert on public.grem1
|
||||
Remote SQL: INSERT INTO public.gloc1(a, b) VALUES ($1, DEFAULT)
|
||||
Remote SQL: INSERT INTO public.gloc1(a, b, c) VALUES ($1, DEFAULT, DEFAULT)
|
||||
Batch Size: 1
|
||||
-> Values Scan on "*VALUES*"
|
||||
Output: "*VALUES*".column1, NULL::integer
|
||||
Output: "*VALUES*".column1, NULL::integer, NULL::integer
|
||||
(5 rows)
|
||||
|
||||
insert into grem1 (a) values (1), (2);
|
||||
explain (verbose, costs off)
|
||||
update grem1 set a = 22 where a = 2;
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------
|
||||
QUERY PLAN
|
||||
----------------------------------------------------------------------------------------
|
||||
Update on public.grem1
|
||||
Remote SQL: UPDATE public.gloc1 SET a = $2, b = DEFAULT WHERE ctid = $1
|
||||
Remote SQL: UPDATE public.gloc1 SET a = $2, b = DEFAULT, c = DEFAULT WHERE ctid = $1
|
||||
-> Foreign Scan on public.grem1
|
||||
Output: 22, ctid, grem1.*
|
||||
Remote SQL: SELECT a, b, ctid FROM public.gloc1 WHERE ((a = 2)) FOR UPDATE
|
||||
Remote SQL: SELECT a, b, c, ctid FROM public.gloc1 WHERE ((a = 2)) FOR UPDATE
|
||||
(5 rows)
|
||||
|
||||
update grem1 set a = 22 where a = 2;
|
||||
select * from gloc1;
|
||||
a | b
|
||||
----+----
|
||||
1 | 2
|
||||
22 | 44
|
||||
a | b | c
|
||||
----+----+---
|
||||
1 | 2 |
|
||||
22 | 44 |
|
||||
(2 rows)
|
||||
|
||||
select * from grem1;
|
||||
a | b
|
||||
----+----
|
||||
1 | 2
|
||||
22 | 44
|
||||
a | b | c
|
||||
----+----+----
|
||||
1 | 2 | 3
|
||||
22 | 44 | 66
|
||||
(2 rows)
|
||||
|
||||
delete from grem1;
|
||||
-- test copy from
|
||||
copy grem1 from stdin;
|
||||
select * from gloc1;
|
||||
a | b
|
||||
---+---
|
||||
1 | 2
|
||||
2 | 4
|
||||
a | b | c
|
||||
---+---+---
|
||||
1 | 2 |
|
||||
2 | 4 |
|
||||
(2 rows)
|
||||
|
||||
select * from grem1;
|
||||
a | b
|
||||
---+---
|
||||
1 | 2
|
||||
2 | 4
|
||||
a | b | c
|
||||
---+---+---
|
||||
1 | 2 | 3
|
||||
2 | 4 | 6
|
||||
(2 rows)
|
||||
|
||||
delete from grem1;
|
||||
@ -7461,28 +7464,28 @@ delete from grem1;
|
||||
alter server loopback options (add batch_size '10');
|
||||
explain (verbose, costs off)
|
||||
insert into grem1 (a) values (1), (2);
|
||||
QUERY PLAN
|
||||
-------------------------------------------------------------------
|
||||
QUERY PLAN
|
||||
-------------------------------------------------------------------------------
|
||||
Insert on public.grem1
|
||||
Remote SQL: INSERT INTO public.gloc1(a, b) VALUES ($1, DEFAULT)
|
||||
Remote SQL: INSERT INTO public.gloc1(a, b, c) VALUES ($1, DEFAULT, DEFAULT)
|
||||
Batch Size: 10
|
||||
-> Values Scan on "*VALUES*"
|
||||
Output: "*VALUES*".column1, NULL::integer
|
||||
Output: "*VALUES*".column1, NULL::integer, NULL::integer
|
||||
(5 rows)
|
||||
|
||||
insert into grem1 (a) values (1), (2);
|
||||
select * from gloc1;
|
||||
a | b
|
||||
---+---
|
||||
1 | 2
|
||||
2 | 4
|
||||
a | b | c
|
||||
---+---+---
|
||||
1 | 2 |
|
||||
2 | 4 |
|
||||
(2 rows)
|
||||
|
||||
select * from grem1;
|
||||
a | b
|
||||
---+---
|
||||
1 | 2
|
||||
2 | 4
|
||||
a | b | c
|
||||
---+---+---
|
||||
1 | 2 | 3
|
||||
2 | 4 | 6
|
||||
(2 rows)
|
||||
|
||||
delete from grem1;
|
||||
|
@ -1859,12 +1859,15 @@ select * from rem1;
|
||||
-- ===================================================================
|
||||
create table gloc1 (
|
||||
a int,
|
||||
b int generated always as (a * 2) stored);
|
||||
b int generated always as (a * 2) stored,
|
||||
c 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');
|
||||
b int generated always as (a * 2) stored,
|
||||
c int generated always as (a * 3) virtual
|
||||
) server loopback options(table_name 'gloc1');
|
||||
explain (verbose, costs off)
|
||||
insert into grem1 (a) values (1), (2);
|
||||
insert into grem1 (a) values (1), (2);
|
||||
|
@ -1307,8 +1307,10 @@
|
||||
</para>
|
||||
<para>
|
||||
If a zero byte (<literal>''</literal>), then not a generated column.
|
||||
Otherwise, <literal>s</literal> = stored. (Other values might be added
|
||||
in the future.)
|
||||
Otherwise, <literal>s</literal> = stored, <literal>v</literal> =
|
||||
virtual. A stored generated column is physically stored like a normal
|
||||
column. A virtual generated column is physically stored as a null
|
||||
value, with the actual value being computed at run time.
|
||||
</para></entry>
|
||||
</row>
|
||||
|
||||
|
@ -361,7 +361,6 @@ INSERT INTO people (id, name, address) VALUES (<emphasis>DEFAULT</emphasis>, 'C'
|
||||
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).
|
||||
<productname>PostgreSQL</productname> currently implements only stored generated columns.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
@ -371,12 +370,12 @@ INSERT INTO people (id, name, address) VALUES (<emphasis>DEFAULT</emphasis>, 'C'
|
||||
CREATE TABLE people (
|
||||
...,
|
||||
height_cm numeric,
|
||||
height_in numeric <emphasis>GENERATED ALWAYS AS (height_cm / 2.54) STORED</emphasis>
|
||||
height_in numeric <emphasis>GENERATED ALWAYS AS (height_cm / 2.54)</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.
|
||||
A generated column is by default of the virtual kind. Use the keywords
|
||||
<literal>VIRTUAL</literal> or <literal>STORED</literal> to make the choice
|
||||
explicit. See <xref linkend="sql-createtable"/> for more details.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
@ -442,12 +441,18 @@ CREATE TABLE people (
|
||||
<listitem>
|
||||
<para>
|
||||
If a parent column is a generated column, its child column must also
|
||||
be a generated column; however, the child column can have a
|
||||
different generation expression. The generation expression that is
|
||||
be a generated column of the same kind (stored or virtual); however,
|
||||
the child column can have a different generation expression.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
For stored generated columns, the generation expression that is
|
||||
actually applied during insert or update of a row is the one
|
||||
associated with the table that the row is physically in.
|
||||
(This is unlike the behavior for column defaults: for those, the
|
||||
default value associated with the table named in the query applies.)
|
||||
associated with the table that the row is physically in. (This is
|
||||
unlike the behavior for column defaults: for those, the default value
|
||||
associated with the table named in the query applies.) For virtual
|
||||
generated columns, the generation expression of the table named in the
|
||||
query applies when a table is read.
|
||||
</para>
|
||||
</listitem>
|
||||
<listitem>
|
||||
@ -502,6 +507,26 @@ CREATE TABLE people (
|
||||
particular role can read from a generated column but not from the
|
||||
underlying base columns.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
For virtual generated columns, this is only fully secure if the
|
||||
generation expression uses only leakproof functions (see <xref
|
||||
linkend="sql-createfunction"/>), but this is not enforced by the system.
|
||||
</para>
|
||||
</listitem>
|
||||
<listitem>
|
||||
<para>
|
||||
Privileges of functions used in generation expressions are checked when
|
||||
the expression is actually executed, on write or read respectively, as
|
||||
if the generation expression had been called directly from the query
|
||||
using the generated column. The user of a generated column must have
|
||||
permissions to call all functions used by the generation expression.
|
||||
Functions in the generation expression are executed with the privileges
|
||||
of the user executing the query or the function owner, depending on
|
||||
whether the functions are defined as <literal>SECURITY INVOKER</literal>
|
||||
or <literal>SECURITY DEFINER</literal>.
|
||||
<!-- matches create_view.sgml -->
|
||||
</para>
|
||||
</listitem>
|
||||
<listitem>
|
||||
<para>
|
||||
@ -519,6 +544,7 @@ CREATE TABLE people (
|
||||
<link linkend="sql-createpublication-params-with-publish-generated-columns">
|
||||
<literal>publish_generated_columns</literal></link> or by including them
|
||||
in the column list of the <command>CREATE PUBLICATION</command> command.
|
||||
This is currently only supported for stored generated columns.
|
||||
See <xref linkend="logical-replication-gencols"/> for details.
|
||||
</para>
|
||||
</listitem>
|
||||
|
@ -102,7 +102,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
|
||||
NULL |
|
||||
CHECK ( <replaceable class="parameter">expression</replaceable> ) [ NO INHERIT ] |
|
||||
DEFAULT <replaceable>default_expr</replaceable> |
|
||||
GENERATED ALWAYS AS ( <replaceable>generation_expr</replaceable> ) STORED |
|
||||
GENERATED ALWAYS AS ( <replaceable>generation_expr</replaceable> ) [ STORED | VIRTUAL ] |
|
||||
GENERATED { ALWAYS | BY DEFAULT } AS IDENTITY [ ( <replaceable>sequence_options</replaceable> ) ] |
|
||||
UNIQUE [ NULLS [ NOT ] DISTINCT ] <replaceable class="parameter">index_parameters</replaceable> |
|
||||
PRIMARY KEY <replaceable class="parameter">index_parameters</replaceable> |
|
||||
@ -264,8 +264,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
|
||||
<listitem>
|
||||
<para>
|
||||
This form replaces the expression of a generated column. Existing data
|
||||
in the column is rewritten and all the future changes will apply the new
|
||||
generation expression.
|
||||
in a stored generated column is rewritten and all the future changes
|
||||
will apply the new generation expression.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
@ -279,10 +279,15 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
|
||||
longer apply the generation expression.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
This form is currently only supported for stored generated columns (not
|
||||
virtual ones).
|
||||
</para>
|
||||
|
||||
<para>
|
||||
If <literal>DROP EXPRESSION IF EXISTS</literal> is specified and the
|
||||
column is not a stored generated column, no error is thrown. In this
|
||||
case a notice is issued instead.
|
||||
column is not a generated column, no error is thrown. In this case a
|
||||
notice is issued instead.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
@ -47,7 +47,7 @@ CREATE FOREIGN TABLE [ IF NOT EXISTS ] <replaceable class="parameter">table_name
|
||||
NULL |
|
||||
CHECK ( <replaceable class="parameter">expression</replaceable> ) [ NO INHERIT ] |
|
||||
DEFAULT <replaceable>default_expr</replaceable> |
|
||||
GENERATED ALWAYS AS ( <replaceable>generation_expr</replaceable> ) STORED }
|
||||
GENERATED ALWAYS AS ( <replaceable>generation_expr</replaceable> ) [ STORED | VIRTUAL ] }
|
||||
[ ENFORCED | NOT ENFORCED ]
|
||||
|
||||
<phrase>and <replaceable class="parameter">table_constraint</replaceable> is:</phrase>
|
||||
@ -283,7 +283,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>GENERATED ALWAYS AS ( <replaceable>generation_expr</replaceable> ) STORED</literal><indexterm><primary>generated column</primary></indexterm></term>
|
||||
<term><literal>GENERATED ALWAYS AS ( <replaceable>generation_expr</replaceable> ) [ STORED | VIRTUAL ]</literal><indexterm><primary>generated column</primary></indexterm></term>
|
||||
<listitem>
|
||||
<para>
|
||||
This clause creates the column as a <firstterm>generated
|
||||
@ -292,10 +292,13 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
|
||||
</para>
|
||||
|
||||
<para>
|
||||
The keyword <literal>STORED</literal> is required to signify that the
|
||||
When <literal>VIRTUAL</literal> is specified, the column will be
|
||||
computed when it is read. (The foreign-data wrapper will see it as a
|
||||
null value in new rows and may choose to store it as a null value or
|
||||
ignore it altogether.) When <literal>STORED</literal> is specified, 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.)
|
||||
reading.) <literal>VIRTUAL</literal> is the default.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
|
@ -65,7 +65,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 AS ( <replaceable>generation_expr</replaceable> ) [ STORED | VIRTUAL ] |
|
||||
GENERATED { ALWAYS | BY DEFAULT } AS IDENTITY [ ( <replaceable>sequence_options</replaceable> ) ] |
|
||||
UNIQUE [ NULLS [ NOT ] DISTINCT ] <replaceable class="parameter">index_parameters</replaceable> |
|
||||
PRIMARY KEY <replaceable class="parameter">index_parameters</replaceable> |
|
||||
@ -725,8 +725,9 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
|
||||
<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.
|
||||
Any generation expressions as well as the stored/virtual choice of
|
||||
copied column definitions will be copied. By default, new columns
|
||||
will be regular base columns.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
@ -907,7 +908,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry id="sql-createtable-parms-generated-stored">
|
||||
<term><literal>GENERATED ALWAYS AS ( <replaceable>generation_expr</replaceable> ) STORED</literal><indexterm><primary>generated column</primary></indexterm></term>
|
||||
<term><literal>GENERATED ALWAYS AS ( <replaceable>generation_expr</replaceable> ) [ STORED | VIRTUAL ]</literal><indexterm><primary>generated column</primary></indexterm></term>
|
||||
<listitem>
|
||||
<para>
|
||||
This clause creates the column as a <firstterm>generated
|
||||
@ -916,8 +917,11 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
|
||||
</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.
|
||||
When <literal>VIRTUAL</literal> is specified, the column will be
|
||||
computed when it is read, and it will not occupy any storage. When
|
||||
<literal>STORED</literal> is specified, the column will be computed on
|
||||
write and will be stored on disk. <literal>VIRTUAL</literal> is the
|
||||
default.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
@ -2504,9 +2508,9 @@ CREATE TABLE cities_partdef
|
||||
<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.
|
||||
The options <literal>STORED</literal> and <literal>VIRTUAL</literal> are
|
||||
not standard but are also used by other SQL implementations. The SQL
|
||||
standard does not specify the storage of generated columns.
|
||||
</para>
|
||||
</refsect2>
|
||||
|
||||
|
@ -293,6 +293,10 @@
|
||||
<literal>BEFORE</literal> trigger. Changes to the value of a generated
|
||||
column in a <literal>BEFORE</literal> trigger are ignored and will be
|
||||
overwritten.
|
||||
Virtual generated columns are never computed when triggers fire. In the C
|
||||
language interface, their content is undefined in a trigger function.
|
||||
Higher-level programming languages should prevent access to virtual
|
||||
generated columns in triggers.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
|
@ -342,6 +342,7 @@ CreateTupleDescCopyConstr(TupleDesc tupdesc)
|
||||
|
||||
cpy->has_not_null = constr->has_not_null;
|
||||
cpy->has_generated_stored = constr->has_generated_stored;
|
||||
cpy->has_generated_virtual = constr->has_generated_virtual;
|
||||
|
||||
if ((cpy->num_defval = constr->num_defval) > 0)
|
||||
{
|
||||
@ -640,6 +641,8 @@ equalTupleDescs(TupleDesc tupdesc1, TupleDesc tupdesc2)
|
||||
return false;
|
||||
if (constr1->has_generated_stored != constr2->has_generated_stored)
|
||||
return false;
|
||||
if (constr1->has_generated_virtual != constr2->has_generated_virtual)
|
||||
return false;
|
||||
n = constr1->num_defval;
|
||||
if (n != (int) constr2->num_defval)
|
||||
return false;
|
||||
|
@ -2047,6 +2047,8 @@ heapam_relation_needs_toast_table(Relation rel)
|
||||
|
||||
if (att->attisdropped)
|
||||
continue;
|
||||
if (att->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
continue;
|
||||
data_length = att_align_nominal(data_length, att->attalign);
|
||||
if (att->attlen > 0)
|
||||
{
|
||||
|
@ -507,7 +507,7 @@ CheckAttributeNamesTypes(TupleDesc tupdesc, char relkind,
|
||||
TupleDescAttr(tupdesc, i)->atttypid,
|
||||
TupleDescAttr(tupdesc, i)->attcollation,
|
||||
NIL, /* assume we're creating a new rowtype */
|
||||
flags);
|
||||
flags | (TupleDescAttr(tupdesc, i)->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL ? CHKATYPE_IS_VIRTUAL : 0));
|
||||
}
|
||||
}
|
||||
|
||||
@ -582,6 +582,17 @@ CheckAttributeType(const char *attname,
|
||||
}
|
||||
else if (att_typtype == TYPTYPE_DOMAIN)
|
||||
{
|
||||
/*
|
||||
* Prevent virtual generated columns from having a domain type. We
|
||||
* would have to enforce domain constraints when columns underlying
|
||||
* the generated column change. This could possibly be implemented,
|
||||
* but it's not.
|
||||
*/
|
||||
if (flags & CHKATYPE_IS_VIRTUAL)
|
||||
ereport(ERROR,
|
||||
errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("virtual generated column \"%s\" cannot have a domain type", attname));
|
||||
|
||||
/*
|
||||
* If it's a domain, recurse to check its base type.
|
||||
*/
|
||||
@ -2553,6 +2564,11 @@ AddRelationNewConstraints(Relation rel,
|
||||
errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("cannot add not-null constraint on system column \"%s\"",
|
||||
strVal(linitial(cdef->keys))));
|
||||
/* TODO: see transformColumnDefinition() */
|
||||
if (get_attgenerated(RelationGetRelid(rel), colnum) == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
ereport(ERROR,
|
||||
errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("not-null constraints are not supported on virtual generated columns"));
|
||||
|
||||
/*
|
||||
* If the column already has a not-null constraint, we don't want
|
||||
@ -2868,6 +2884,11 @@ AddRelationNotNullConstraints(Relation rel, List *constraints,
|
||||
errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("cannot add not-null constraint on system column \"%s\"",
|
||||
strVal(linitial(constr->keys))));
|
||||
/* TODO: see transformColumnDefinition() */
|
||||
if (get_attgenerated(RelationGetRelid(rel), attnum) == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
ereport(ERROR,
|
||||
errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("not-null constraints are not supported on virtual generated columns"));
|
||||
|
||||
/*
|
||||
* A column can only have one not-null constraint, so discard any
|
||||
|
@ -546,7 +546,8 @@ publication_add_relation(Oid pubid, PublicationRelInfo *pri,
|
||||
* pub_collist_validate
|
||||
* Process and validate the 'columns' list and ensure the columns are all
|
||||
* valid to use for a publication. Checks for and raises an ERROR for
|
||||
* any unknown columns, system columns, or duplicate columns.
|
||||
* any unknown columns, system columns, duplicate columns, or virtual
|
||||
* generated columns.
|
||||
*
|
||||
* Looks up each column's attnum and returns a 0-based Bitmapset of the
|
||||
* corresponding attnums.
|
||||
@ -556,6 +557,7 @@ pub_collist_validate(Relation targetrel, List *columns)
|
||||
{
|
||||
Bitmapset *set = NULL;
|
||||
ListCell *lc;
|
||||
TupleDesc tupdesc = RelationGetDescr(targetrel);
|
||||
|
||||
foreach(lc, columns)
|
||||
{
|
||||
@ -574,6 +576,12 @@ pub_collist_validate(Relation targetrel, List *columns)
|
||||
errmsg("cannot use system column \"%s\" in publication column list",
|
||||
colname));
|
||||
|
||||
if (TupleDescAttr(tupdesc, attnum - 1)->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
ereport(ERROR,
|
||||
errcode(ERRCODE_INVALID_COLUMN_REFERENCE),
|
||||
errmsg("cannot use virtual generated column \"%s\" in publication column list",
|
||||
colname));
|
||||
|
||||
if (bms_is_member(attnum, set))
|
||||
ereport(ERROR,
|
||||
errcode(ERRCODE_DUPLICATE_OBJECT),
|
||||
|
@ -1039,6 +1039,10 @@ examine_attribute(Relation onerel, int attnum, Node *index_expr)
|
||||
if (attr->attisdropped)
|
||||
return NULL;
|
||||
|
||||
/* Don't analyze virtual generated columns */
|
||||
if (attr->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
return NULL;
|
||||
|
||||
/*
|
||||
* Get attstattarget value. Set to -1 if null. (Analyze functions expect
|
||||
* -1 to mean use default_statistics_target; see for example
|
||||
|
@ -1110,6 +1110,9 @@ DefineIndex(Oid tableId,
|
||||
/*
|
||||
* We disallow indexes on system columns. They would not necessarily get
|
||||
* updated correctly, and they don't seem useful anyway.
|
||||
*
|
||||
* Also disallow virtual generated columns in indexes (use expression
|
||||
* index instead).
|
||||
*/
|
||||
for (int i = 0; i < indexInfo->ii_NumIndexAttrs; i++)
|
||||
{
|
||||
@ -1119,14 +1122,24 @@ DefineIndex(Oid tableId,
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("index creation on system columns is not supported")));
|
||||
|
||||
|
||||
if (TupleDescAttr(RelationGetDescr(rel), attno - 1)->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
stmt->isconstraint ?
|
||||
errmsg("unique constraints on virtual generated columns are not supported") :
|
||||
errmsg("indexes on virtual generated columns are not supported")));
|
||||
}
|
||||
|
||||
/*
|
||||
* Also check for system columns used in expressions or predicates.
|
||||
* Also check for system and generated columns used in expressions or
|
||||
* predicates.
|
||||
*/
|
||||
if (indexInfo->ii_Expressions || indexInfo->ii_Predicate)
|
||||
{
|
||||
Bitmapset *indexattrs = NULL;
|
||||
int j;
|
||||
|
||||
pull_varattnos((Node *) indexInfo->ii_Expressions, 1, &indexattrs);
|
||||
pull_varattnos((Node *) indexInfo->ii_Predicate, 1, &indexattrs);
|
||||
@ -1139,6 +1152,24 @@ DefineIndex(Oid tableId,
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("index creation on system columns is not supported")));
|
||||
}
|
||||
|
||||
/*
|
||||
* XXX Virtual generated columns in index expressions or predicates
|
||||
* could be supported, but it needs support in
|
||||
* RelationGetIndexExpressions() and RelationGetIndexPredicate().
|
||||
*/
|
||||
j = -1;
|
||||
while ((j = bms_next_member(indexattrs, j)) >= 0)
|
||||
{
|
||||
AttrNumber attno = j + FirstLowInvalidHeapAttributeNumber;
|
||||
|
||||
if (TupleDescAttr(RelationGetDescr(rel), attno - 1)->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
stmt->isconstraint ?
|
||||
errmsg("unique constraints on virtual generated columns are not supported") :
|
||||
errmsg("indexes on virtual generated columns are not supported")));
|
||||
}
|
||||
}
|
||||
|
||||
/* Is index safe for others to ignore? See set_indexsafe_procflags() */
|
||||
|
@ -38,6 +38,7 @@
|
||||
#include "parser/parse_clause.h"
|
||||
#include "parser/parse_collate.h"
|
||||
#include "parser/parse_relation.h"
|
||||
#include "rewrite/rewriteHandler.h"
|
||||
#include "storage/lmgr.h"
|
||||
#include "utils/acl.h"
|
||||
#include "utils/builtins.h"
|
||||
@ -404,6 +405,14 @@ pub_contains_invalid_column(Oid pubid, Relation relation, List *ancestors,
|
||||
relation->rd_att->constr->has_generated_stored)
|
||||
*invalid_gen_col = true;
|
||||
|
||||
/*
|
||||
* Virtual generated columns are currently not supported for logical
|
||||
* replication at all.
|
||||
*/
|
||||
if (relation->rd_att->constr &&
|
||||
relation->rd_att->constr->has_generated_virtual)
|
||||
*invalid_gen_col = true;
|
||||
|
||||
if (*invalid_gen_col && *invalid_column_list)
|
||||
return true;
|
||||
}
|
||||
@ -430,7 +439,17 @@ pub_contains_invalid_column(Oid pubid, Relation relation, List *ancestors,
|
||||
* The publish_generated_columns option must be set to stored if
|
||||
* the REPLICA IDENTITY contains any stored generated column.
|
||||
*/
|
||||
if (pubgencols_type != PUBLISH_GENCOLS_STORED && att->attgenerated)
|
||||
if (att->attgenerated == ATTRIBUTE_GENERATED_STORED && pubgencols_type != PUBLISH_GENCOLS_STORED)
|
||||
{
|
||||
*invalid_gen_col = true;
|
||||
break;
|
||||
}
|
||||
|
||||
/*
|
||||
* The equivalent setting for virtual generated columns does not
|
||||
* exist yet.
|
||||
*/
|
||||
if (att->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
{
|
||||
*invalid_gen_col = true;
|
||||
break;
|
||||
@ -689,6 +708,8 @@ TransformPubWhereClauses(List *tables, const char *queryString,
|
||||
/* Fix up collation information */
|
||||
assign_expr_collations(pstate, whereclause);
|
||||
|
||||
whereclause = expand_generated_columns_in_expr(whereclause, pri->relation, 1);
|
||||
|
||||
/*
|
||||
* We allow only simple expressions in row filters. See
|
||||
* check_simple_rowfilter_expr_walker.
|
||||
|
@ -246,6 +246,12 @@ CreateStatistics(CreateStatsStmt *stmt)
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("statistics creation on system columns is not supported")));
|
||||
|
||||
/* Disallow use of virtual generated columns in extended stats */
|
||||
if (attForm->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("statistics creation on virtual generated columns is not supported")));
|
||||
|
||||
/* Disallow data types without a less-than operator */
|
||||
type = lookup_type_cache(attForm->atttypid, TYPECACHE_LT_OPR);
|
||||
if (type->lt_opr == InvalidOid)
|
||||
@ -269,6 +275,12 @@ CreateStatistics(CreateStatsStmt *stmt)
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("statistics creation on system columns is not supported")));
|
||||
|
||||
/* Disallow use of virtual generated columns in extended stats */
|
||||
if (get_attgenerated(relid, var->varattno) == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("statistics creation on virtual generated columns is not supported")));
|
||||
|
||||
/* Disallow data types without a less-than operator */
|
||||
type = lookup_type_cache(var->vartype, TYPECACHE_LT_OPR);
|
||||
if (type->lt_opr == InvalidOid)
|
||||
@ -290,7 +302,6 @@ CreateStatistics(CreateStatsStmt *stmt)
|
||||
|
||||
Assert(expr != NULL);
|
||||
|
||||
/* Disallow expressions referencing system attributes. */
|
||||
pull_varattnos(expr, 1, &attnums);
|
||||
|
||||
k = -1;
|
||||
@ -298,10 +309,17 @@ CreateStatistics(CreateStatsStmt *stmt)
|
||||
{
|
||||
AttrNumber attnum = k + FirstLowInvalidHeapAttributeNumber;
|
||||
|
||||
/* Disallow expressions referencing system attributes. */
|
||||
if (attnum <= 0)
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("statistics creation on system columns is not supported")));
|
||||
|
||||
/* Disallow use of virtual generated columns in extended stats */
|
||||
if (get_attgenerated(relid, attnum) == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("statistics creation on virtual generated columns is not supported")));
|
||||
}
|
||||
|
||||
/*
|
||||
|
@ -3039,6 +3039,15 @@ MergeAttributes(List *columns, const List *supers, char relpersistence,
|
||||
errhint("A child table column cannot be generated unless its parent column is.")));
|
||||
}
|
||||
|
||||
if (coldef->generated && restdef->generated && coldef->generated != restdef->generated)
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_INVALID_COLUMN_DEFINITION),
|
||||
errmsg("column \"%s\" inherits from generated column of different kind",
|
||||
restdef->colname),
|
||||
errdetail("Parent column is %s, child column is %s.",
|
||||
coldef->generated == ATTRIBUTE_GENERATED_STORED ? "STORED" : "VIRTUAL",
|
||||
restdef->generated == ATTRIBUTE_GENERATED_STORED ? "STORED" : "VIRTUAL")));
|
||||
|
||||
/*
|
||||
* Override the parent's default value for this column
|
||||
* (coldef->cooked_default) with the partition's local
|
||||
@ -3324,6 +3333,15 @@ MergeChildAttribute(List *inh_columns, int exist_attno, int newcol_attno, const
|
||||
errhint("A child table column cannot be generated unless its parent column is.")));
|
||||
}
|
||||
|
||||
if (inhdef->generated && newdef->generated && newdef->generated != inhdef->generated)
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_INVALID_COLUMN_DEFINITION),
|
||||
errmsg("column \"%s\" inherits from generated column of different kind",
|
||||
inhdef->colname),
|
||||
errdetail("Parent column is %s, child column is %s.",
|
||||
inhdef->generated == ATTRIBUTE_GENERATED_STORED ? "STORED" : "VIRTUAL",
|
||||
newdef->generated == ATTRIBUTE_GENERATED_STORED ? "STORED" : "VIRTUAL")));
|
||||
|
||||
/*
|
||||
* If new def has a default, override previous default
|
||||
*/
|
||||
@ -6130,7 +6148,7 @@ ATRewriteTable(AlteredTableInfo *tab, Oid OIDNewHeap)
|
||||
{
|
||||
case CONSTR_CHECK:
|
||||
needscan = true;
|
||||
con->qualstate = ExecPrepareExpr((Expr *) con->qual, estate);
|
||||
con->qualstate = ExecPrepareExpr((Expr *) expand_generated_columns_in_expr(con->qual, newrel ? newrel : oldrel, 1), estate);
|
||||
break;
|
||||
case CONSTR_FOREIGN:
|
||||
/* Nothing to do here */
|
||||
@ -7308,7 +7326,7 @@ ATExecAddColumn(List **wqueue, AlteredTableInfo *tab, Relation rel,
|
||||
* DEFAULT value outside of the heap. This may be disabled inside
|
||||
* AddRelationNewConstraints if the optimization cannot be applied.
|
||||
*/
|
||||
rawEnt->missingMode = (!colDef->generated);
|
||||
rawEnt->missingMode = (colDef->generated != ATTRIBUTE_GENERATED_STORED);
|
||||
|
||||
rawEnt->generated = colDef->generated;
|
||||
|
||||
@ -7785,6 +7803,14 @@ ATExecSetNotNull(List **wqueue, Relation rel, char *conName, char *colName,
|
||||
errmsg("cannot alter system column \"%s\"",
|
||||
colName)));
|
||||
|
||||
/* TODO: see transformColumnDefinition() */
|
||||
if (TupleDescAttr(RelationGetDescr(rel), attnum - 1)->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("not-null constraints are not supported on virtual generated columns"),
|
||||
errdetail("Column \"%s\" of relation \"%s\" is a virtual generated column.",
|
||||
colName, RelationGetRelationName(rel))));
|
||||
|
||||
/* See if there's already a constraint */
|
||||
tuple = findNotNullConstraintAttnum(RelationGetRelid(rel), attnum);
|
||||
if (HeapTupleIsValid(tuple))
|
||||
@ -8411,6 +8437,8 @@ ATExecSetExpression(AlteredTableInfo *tab, Relation rel, const char *colName,
|
||||
HeapTuple tuple;
|
||||
Form_pg_attribute attTup;
|
||||
AttrNumber attnum;
|
||||
char attgenerated;
|
||||
bool rewrite;
|
||||
Oid attrdefoid;
|
||||
ObjectAddress address;
|
||||
Expr *defval;
|
||||
@ -8425,36 +8453,70 @@ ATExecSetExpression(AlteredTableInfo *tab, Relation rel, const char *colName,
|
||||
colName, RelationGetRelationName(rel))));
|
||||
|
||||
attTup = (Form_pg_attribute) GETSTRUCT(tuple);
|
||||
attnum = attTup->attnum;
|
||||
|
||||
attnum = attTup->attnum;
|
||||
if (attnum <= 0)
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("cannot alter system column \"%s\"",
|
||||
colName)));
|
||||
|
||||
if (attTup->attgenerated != ATTRIBUTE_GENERATED_STORED)
|
||||
attgenerated = attTup->attgenerated;
|
||||
if (!attgenerated)
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
|
||||
errmsg("column \"%s\" of relation \"%s\" is not a generated column",
|
||||
colName, RelationGetRelationName(rel))));
|
||||
|
||||
/*
|
||||
* TODO: This could be done, just need to recheck any constraints
|
||||
* afterwards.
|
||||
*/
|
||||
if (attgenerated == ATTRIBUTE_GENERATED_VIRTUAL &&
|
||||
rel->rd_att->constr && rel->rd_att->constr->num_check > 0)
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("ALTER TABLE / SET EXPRESSION is not supported for virtual generated columns on tables with check constraints"),
|
||||
errdetail("Column \"%s\" of relation \"%s\" is a virtual generated column.",
|
||||
colName, RelationGetRelationName(rel))));
|
||||
|
||||
/*
|
||||
* We need to prevent this because a change of expression could affect a
|
||||
* row filter and inject expressions that are not permitted in a row
|
||||
* filter. XXX We could try to have a more precise check to catch only
|
||||
* publications with row filters, or even re-verify the row filter
|
||||
* expressions.
|
||||
*/
|
||||
if (attgenerated == ATTRIBUTE_GENERATED_VIRTUAL &&
|
||||
GetRelationPublications(RelationGetRelid(rel)) != NIL)
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("ALTER TABLE / SET EXPRESSION is not supported for virtual generated columns on tables that are part of a publication"),
|
||||
errdetail("Column \"%s\" of relation \"%s\" is a virtual generated column.",
|
||||
colName, RelationGetRelationName(rel))));
|
||||
|
||||
rewrite = (attgenerated == ATTRIBUTE_GENERATED_STORED);
|
||||
|
||||
ReleaseSysCache(tuple);
|
||||
|
||||
/*
|
||||
* Clear all the missing values if we're rewriting the table, since this
|
||||
* renders them pointless.
|
||||
*/
|
||||
RelationClearMissing(rel);
|
||||
if (rewrite)
|
||||
{
|
||||
/*
|
||||
* Clear all the missing values if we're rewriting the table, since
|
||||
* this renders them pointless.
|
||||
*/
|
||||
RelationClearMissing(rel);
|
||||
|
||||
/* make sure we don't conflict with later attribute modifications */
|
||||
CommandCounterIncrement();
|
||||
/* make sure we don't conflict with later attribute modifications */
|
||||
CommandCounterIncrement();
|
||||
|
||||
/*
|
||||
* Find everything that depends on the column (constraints, indexes, etc),
|
||||
* and record enough information to let us recreate the objects after
|
||||
* rewrite.
|
||||
*/
|
||||
RememberAllDependentForRebuilding(tab, AT_SetExpression, rel, attnum, colName);
|
||||
/*
|
||||
* Find everything that depends on the column (constraints, indexes,
|
||||
* etc), and record enough information to let us recreate the objects
|
||||
* after rewrite.
|
||||
*/
|
||||
RememberAllDependentForRebuilding(tab, AT_SetExpression, rel, attnum, colName);
|
||||
}
|
||||
|
||||
/*
|
||||
* Drop the dependency records of the GENERATED expression, in particular
|
||||
@ -8483,7 +8545,7 @@ ATExecSetExpression(AlteredTableInfo *tab, Relation rel, const char *colName,
|
||||
rawEnt->attnum = attnum;
|
||||
rawEnt->raw_default = newExpr;
|
||||
rawEnt->missingMode = false;
|
||||
rawEnt->generated = ATTRIBUTE_GENERATED_STORED;
|
||||
rawEnt->generated = attgenerated;
|
||||
|
||||
/* Store the generated expression */
|
||||
AddRelationNewConstraints(rel, list_make1(rawEnt), NIL,
|
||||
@ -8492,16 +8554,19 @@ ATExecSetExpression(AlteredTableInfo *tab, Relation rel, const char *colName,
|
||||
/* Make above new expression visible */
|
||||
CommandCounterIncrement();
|
||||
|
||||
/* Prepare for table rewrite */
|
||||
defval = (Expr *) build_column_default(rel, attnum);
|
||||
if (rewrite)
|
||||
{
|
||||
/* Prepare for table rewrite */
|
||||
defval = (Expr *) build_column_default(rel, attnum);
|
||||
|
||||
newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
|
||||
newval->attnum = attnum;
|
||||
newval->expr = expression_planner(defval);
|
||||
newval->is_generated = true;
|
||||
newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue));
|
||||
newval->attnum = attnum;
|
||||
newval->expr = expression_planner(defval);
|
||||
newval->is_generated = true;
|
||||
|
||||
tab->newvals = lappend(tab->newvals, newval);
|
||||
tab->rewrite |= AT_REWRITE_DEFAULT_VAL;
|
||||
tab->newvals = lappend(tab->newvals, newval);
|
||||
tab->rewrite |= AT_REWRITE_DEFAULT_VAL;
|
||||
}
|
||||
|
||||
/* Drop any pg_statistic entry for the column */
|
||||
RemoveStatistics(RelationGetRelid(rel), attnum);
|
||||
@ -8590,17 +8655,30 @@ ATExecDropExpression(Relation rel, const char *colName, bool missing_ok, LOCKMOD
|
||||
errmsg("cannot alter system column \"%s\"",
|
||||
colName)));
|
||||
|
||||
if (attTup->attgenerated != ATTRIBUTE_GENERATED_STORED)
|
||||
/*
|
||||
* TODO: This could be done, but it would need a table rewrite to
|
||||
* materialize the generated values. Note that for the time being, we
|
||||
* still error with missing_ok, so that we don't silently leave the column
|
||||
* as generated.
|
||||
*/
|
||||
if (attTup->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("ALTER TABLE / DROP EXPRESSION is not supported for virtual generated columns"),
|
||||
errdetail("Column \"%s\" of relation \"%s\" is a virtual generated column.",
|
||||
colName, RelationGetRelationName(rel))));
|
||||
|
||||
if (!attTup->attgenerated)
|
||||
{
|
||||
if (!missing_ok)
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
|
||||
errmsg("column \"%s\" of relation \"%s\" is not a stored generated column",
|
||||
errmsg("column \"%s\" of relation \"%s\" is not a generated column",
|
||||
colName, RelationGetRelationName(rel))));
|
||||
else
|
||||
{
|
||||
ereport(NOTICE,
|
||||
(errmsg("column \"%s\" of relation \"%s\" is not a stored generated column, skipping",
|
||||
(errmsg("column \"%s\" of relation \"%s\" is not a generated column, skipping",
|
||||
colName, RelationGetRelationName(rel))));
|
||||
heap_freetuple(tuple);
|
||||
table_close(attrelation, RowExclusiveLock);
|
||||
@ -8743,6 +8821,16 @@ ATExecSetStatistics(Relation rel, const char *colName, int16 colNum, Node *newVa
|
||||
errmsg("cannot alter system column \"%s\"",
|
||||
colName)));
|
||||
|
||||
/*
|
||||
* Prevent this as long as the ANALYZE code skips virtual generated
|
||||
* columns.
|
||||
*/
|
||||
if (attrtuple->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("cannot alter statistics on virtual generated column \"%s\"",
|
||||
colName)));
|
||||
|
||||
if (rel->rd_rel->relkind == RELKIND_INDEX ||
|
||||
rel->rd_rel->relkind == RELKIND_PARTITIONED_INDEX)
|
||||
{
|
||||
@ -9925,6 +10013,19 @@ ATAddForeignKeyConstraint(List **wqueue, AlteredTableInfo *tab, Relation rel,
|
||||
errmsg("invalid %s action for foreign key constraint containing generated column",
|
||||
"ON DELETE")));
|
||||
}
|
||||
|
||||
/*
|
||||
* FKs on virtual columns are not supported. This would require
|
||||
* various additional support in ri_triggers.c, including special
|
||||
* handling in ri_NullCheck(), ri_KeysEqual(),
|
||||
* RI_FKey_fk_upd_check_required() (since all virtual columns appear
|
||||
* as NULL there). Also not really practical as long as you can't
|
||||
* index virtual columns.
|
||||
*/
|
||||
if (attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("foreign key constraints on virtual generated columns are not supported")));
|
||||
}
|
||||
|
||||
/*
|
||||
@ -12289,7 +12390,7 @@ QueueCheckConstraintValidation(List **wqueue, Relation conrel, Relation rel,
|
||||
val = SysCacheGetAttrNotNull(CONSTROID, contuple,
|
||||
Anum_pg_constraint_conbin);
|
||||
conbin = TextDatumGetCString(val);
|
||||
newcon->qual = (Node *) stringToNode(conbin);
|
||||
newcon->qual = expand_generated_columns_in_expr(stringToNode(conbin), rel, 1);
|
||||
|
||||
/* Find or create work queue entry for this table */
|
||||
tab = ATGetQueueEntry(wqueue, rel);
|
||||
@ -13467,8 +13568,12 @@ ATPrepAlterColumnType(List **wqueue,
|
||||
list_make1_oid(rel->rd_rel->reltype),
|
||||
0);
|
||||
|
||||
if (tab->relkind == RELKIND_RELATION ||
|
||||
tab->relkind == RELKIND_PARTITIONED_TABLE)
|
||||
if (attTup->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
{
|
||||
/* do nothing */
|
||||
}
|
||||
else if (tab->relkind == RELKIND_RELATION ||
|
||||
tab->relkind == RELKIND_PARTITIONED_TABLE)
|
||||
{
|
||||
/*
|
||||
* Set up an expression to transform the old data value to the new
|
||||
@ -13541,11 +13646,12 @@ ATPrepAlterColumnType(List **wqueue,
|
||||
errmsg("\"%s\" is not a table",
|
||||
RelationGetRelationName(rel))));
|
||||
|
||||
if (!RELKIND_HAS_STORAGE(tab->relkind))
|
||||
if (!RELKIND_HAS_STORAGE(tab->relkind) || attTup->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
{
|
||||
/*
|
||||
* For relations without storage, do this check now. Regular tables
|
||||
* will check it later when the table is being rewritten.
|
||||
* For relations or columns without storage, do this check now.
|
||||
* Regular tables will check it later when the table is being
|
||||
* rewritten.
|
||||
*/
|
||||
find_composite_type_dependencies(rel->rd_rel->reltype, rel, NULL);
|
||||
}
|
||||
@ -16534,6 +16640,14 @@ MergeAttributesIntoExisting(Relation child_rel, Relation parent_rel, bool ispart
|
||||
(errcode(ERRCODE_DATATYPE_MISMATCH),
|
||||
errmsg("column \"%s\" in child table must not be a generated column", parent_attname)));
|
||||
|
||||
if (parent_att->attgenerated && child_att->attgenerated && child_att->attgenerated != parent_att->attgenerated)
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_DATATYPE_MISMATCH),
|
||||
errmsg("column \"%s\" inherits from generated column of different kind", parent_attname),
|
||||
errdetail("Parent column is %s, child column is %s.",
|
||||
parent_att->attgenerated == ATTRIBUTE_GENERATED_STORED ? "STORED" : "VIRTUAL",
|
||||
child_att->attgenerated == ATTRIBUTE_GENERATED_STORED ? "STORED" : "VIRTUAL")));
|
||||
|
||||
/*
|
||||
* Regular inheritance children are independent enough not to
|
||||
* inherit identity columns. But partitions are integral part of
|
||||
@ -18781,8 +18895,11 @@ ComputePartitionAttrs(ParseState *pstate, Relation rel, List *partParams, AttrNu
|
||||
parser_errposition(pstate, pelem->location)));
|
||||
|
||||
/*
|
||||
* Generated columns cannot work: They are computed after BEFORE
|
||||
* triggers, but partition routing is done before all triggers.
|
||||
* Stored generated columns cannot work: They are computed after
|
||||
* BEFORE triggers, but partition routing is done before all
|
||||
* triggers. Maybe virtual generated columns could be made to
|
||||
* work, but then they would need to be handled as an expression
|
||||
* below.
|
||||
*/
|
||||
if (attform->attgenerated)
|
||||
ereport(ERROR,
|
||||
@ -18864,9 +18981,12 @@ ComputePartitionAttrs(ParseState *pstate, Relation rel, List *partParams, AttrNu
|
||||
}
|
||||
|
||||
/*
|
||||
* Generated columns cannot work: They are computed after
|
||||
* BEFORE triggers, but partition routing is done before all
|
||||
* triggers.
|
||||
* Stored generated columns cannot work: They are computed
|
||||
* after BEFORE triggers, but partition routing is done before
|
||||
* all triggers. Virtual generated columns could probably
|
||||
* work, but it would require more work elsewhere (for example
|
||||
* SET EXPRESSION would need to check whether the column is
|
||||
* used in partition keys). Seems safer to prohibit for now.
|
||||
*/
|
||||
i = -1;
|
||||
while ((i = bms_next_member(expr_attrs, i)) >= 0)
|
||||
|
@ -43,6 +43,7 @@
|
||||
#include "parser/parse_relation.h"
|
||||
#include "partitioning/partdesc.h"
|
||||
#include "pgstat.h"
|
||||
#include "rewrite/rewriteHandler.h"
|
||||
#include "rewrite/rewriteManip.h"
|
||||
#include "storage/lmgr.h"
|
||||
#include "utils/acl.h"
|
||||
@ -101,6 +102,7 @@ static void AfterTriggerSaveEvent(EState *estate, ResultRelInfo *relinfo,
|
||||
bool is_crosspart_update);
|
||||
static void AfterTriggerEnlargeQueryState(void);
|
||||
static bool before_stmt_triggers_fired(Oid relid, CmdType cmdType);
|
||||
static HeapTuple check_modified_virtual_generated(TupleDesc tupdesc, HeapTuple tuple);
|
||||
|
||||
|
||||
/*
|
||||
@ -641,7 +643,8 @@ CreateTriggerFiringOn(CreateTrigStmt *stmt, const char *queryString,
|
||||
if (TRIGGER_FOR_BEFORE(tgtype) &&
|
||||
var->varattno == 0 &&
|
||||
RelationGetDescr(rel)->constr &&
|
||||
RelationGetDescr(rel)->constr->has_generated_stored)
|
||||
(RelationGetDescr(rel)->constr->has_generated_stored ||
|
||||
RelationGetDescr(rel)->constr->has_generated_virtual))
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
|
||||
errmsg("BEFORE trigger's WHEN condition cannot reference NEW generated columns"),
|
||||
@ -2504,6 +2507,8 @@ ExecBRInsertTriggers(EState *estate, ResultRelInfo *relinfo,
|
||||
}
|
||||
else if (newtuple != oldtuple)
|
||||
{
|
||||
newtuple = check_modified_virtual_generated(RelationGetDescr(relinfo->ri_RelationDesc), newtuple);
|
||||
|
||||
ExecForceStoreHeapTuple(newtuple, slot, false);
|
||||
|
||||
/*
|
||||
@ -3061,6 +3066,8 @@ ExecBRUpdateTriggers(EState *estate, EPQState *epqstate,
|
||||
}
|
||||
else if (newtuple != oldtuple)
|
||||
{
|
||||
newtuple = check_modified_virtual_generated(RelationGetDescr(relinfo->ri_RelationDesc), newtuple);
|
||||
|
||||
ExecForceStoreHeapTuple(newtuple, newslot, false);
|
||||
|
||||
/*
|
||||
@ -3491,6 +3498,8 @@ TriggerEnabled(EState *estate, ResultRelInfo *relinfo,
|
||||
|
||||
oldContext = MemoryContextSwitchTo(estate->es_query_cxt);
|
||||
tgqual = stringToNode(trigger->tgqual);
|
||||
tgqual = expand_generated_columns_in_expr(tgqual, relinfo->ri_RelationDesc, PRS2_OLD_VARNO);
|
||||
tgqual = expand_generated_columns_in_expr(tgqual, relinfo->ri_RelationDesc, PRS2_NEW_VARNO);
|
||||
/* Change references to OLD and NEW to INNER_VAR and OUTER_VAR */
|
||||
ChangeVarNodes(tgqual, PRS2_OLD_VARNO, INNER_VAR, 0);
|
||||
ChangeVarNodes(tgqual, PRS2_NEW_VARNO, OUTER_VAR, 0);
|
||||
@ -6621,3 +6630,37 @@ pg_trigger_depth(PG_FUNCTION_ARGS)
|
||||
{
|
||||
PG_RETURN_INT32(MyTriggerDepth);
|
||||
}
|
||||
|
||||
/*
|
||||
* Check whether a trigger modified a virtual generated column and replace the
|
||||
* value with null if so.
|
||||
*
|
||||
* We need to check this so that we don't end up storing a non-null value in a
|
||||
* virtual generated column.
|
||||
*
|
||||
* We don't need to check for stored generated columns, since those will be
|
||||
* overwritten later anyway.
|
||||
*/
|
||||
static HeapTuple
|
||||
check_modified_virtual_generated(TupleDesc tupdesc, HeapTuple tuple)
|
||||
{
|
||||
if (!(tupdesc->constr && tupdesc->constr->has_generated_virtual))
|
||||
return tuple;
|
||||
|
||||
for (int i = 0; i < tupdesc->natts; i++)
|
||||
{
|
||||
if (TupleDescAttr(tupdesc, i)->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
{
|
||||
if (!heap_attisnull(tuple, i + 1, tupdesc))
|
||||
{
|
||||
int replCol = i + 1;
|
||||
Datum replValue = 0;
|
||||
bool replIsnull = true;
|
||||
|
||||
tuple = heap_modify_tuple_by_cols(tuple, tupdesc, 1, &replCol, &replValue, &replIsnull);
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
return tuple;
|
||||
}
|
||||
|
@ -2324,6 +2324,10 @@ CheckVarSlotCompatibility(TupleTableSlot *slot, int attnum, Oid vartype)
|
||||
|
||||
attr = TupleDescAttr(slot_tupdesc, attnum - 1);
|
||||
|
||||
/* Internal error: somebody forgot to expand it. */
|
||||
if (attr->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
elog(ERROR, "unexpected virtual generated column reference");
|
||||
|
||||
if (attr->attisdropped)
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_UNDEFINED_COLUMN),
|
||||
|
@ -1781,6 +1781,7 @@ ExecRelCheck(ResultRelInfo *resultRelInfo,
|
||||
continue;
|
||||
|
||||
checkconstr = stringToNode(check[i].ccbin);
|
||||
checkconstr = (Expr *) expand_generated_columns_in_expr((Node *) checkconstr, rel, 1);
|
||||
resultRelInfo->ri_ConstraintExprs[i] =
|
||||
ExecPrepareExpr(checkconstr, estate);
|
||||
}
|
||||
@ -2328,7 +2329,9 @@ ExecBuildSlotValueDescription(Oid reloid,
|
||||
|
||||
if (table_perm || column_perm)
|
||||
{
|
||||
if (slot->tts_isnull[i])
|
||||
if (att->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
val = "virtual";
|
||||
else if (slot->tts_isnull[i])
|
||||
val = "null";
|
||||
else
|
||||
{
|
||||
|
@ -1393,8 +1393,8 @@ Bitmapset *
|
||||
ExecGetExtraUpdatedCols(ResultRelInfo *relinfo, EState *estate)
|
||||
{
|
||||
/* Compute the info if we didn't already */
|
||||
if (relinfo->ri_GeneratedExprsU == NULL)
|
||||
ExecInitStoredGenerated(relinfo, estate, CMD_UPDATE);
|
||||
if (!relinfo->ri_extraUpdatedCols_valid)
|
||||
ExecInitGenerated(relinfo, estate, CMD_UPDATE);
|
||||
return relinfo->ri_extraUpdatedCols;
|
||||
}
|
||||
|
||||
|
@ -391,11 +391,14 @@ ExecCheckTIDVisible(EState *estate,
|
||||
}
|
||||
|
||||
/*
|
||||
* Initialize to compute stored generated columns for a tuple
|
||||
* Initialize generated columns handling for a tuple
|
||||
*
|
||||
* This fills the resultRelInfo's ri_GeneratedExprsI/ri_NumGeneratedNeededI or
|
||||
* ri_GeneratedExprsU/ri_NumGeneratedNeededU fields, depending on cmdtype.
|
||||
* This is used only for stored generated columns.
|
||||
*
|
||||
* This fills the resultRelInfo's ri_GeneratedExprsI/ri_NumGeneratedNeededI
|
||||
* or ri_GeneratedExprsU/ri_NumGeneratedNeededU fields, depending on cmdtype.
|
||||
* If cmdType == CMD_UPDATE, the ri_extraUpdatedCols field is filled too.
|
||||
* This is used by both stored and virtual generated columns.
|
||||
*
|
||||
* Note: usually, a given query would need only one of ri_GeneratedExprsI and
|
||||
* ri_GeneratedExprsU per result rel; but MERGE can need both, and so can
|
||||
@ -403,9 +406,9 @@ ExecCheckTIDVisible(EState *estate,
|
||||
* UPDATE and INSERT actions.
|
||||
*/
|
||||
void
|
||||
ExecInitStoredGenerated(ResultRelInfo *resultRelInfo,
|
||||
EState *estate,
|
||||
CmdType cmdtype)
|
||||
ExecInitGenerated(ResultRelInfo *resultRelInfo,
|
||||
EState *estate,
|
||||
CmdType cmdtype)
|
||||
{
|
||||
Relation rel = resultRelInfo->ri_RelationDesc;
|
||||
TupleDesc tupdesc = RelationGetDescr(rel);
|
||||
@ -416,7 +419,7 @@ ExecInitStoredGenerated(ResultRelInfo *resultRelInfo,
|
||||
MemoryContext oldContext;
|
||||
|
||||
/* Nothing to do if no generated columns */
|
||||
if (!(tupdesc->constr && tupdesc->constr->has_generated_stored))
|
||||
if (!(tupdesc->constr && (tupdesc->constr->has_generated_stored || tupdesc->constr->has_generated_virtual)))
|
||||
return;
|
||||
|
||||
/*
|
||||
@ -442,7 +445,9 @@ ExecInitStoredGenerated(ResultRelInfo *resultRelInfo,
|
||||
|
||||
for (int i = 0; i < natts; i++)
|
||||
{
|
||||
if (TupleDescAttr(tupdesc, i)->attgenerated == ATTRIBUTE_GENERATED_STORED)
|
||||
char attgenerated = TupleDescAttr(tupdesc, i)->attgenerated;
|
||||
|
||||
if (attgenerated)
|
||||
{
|
||||
Expr *expr;
|
||||
|
||||
@ -467,8 +472,11 @@ ExecInitStoredGenerated(ResultRelInfo *resultRelInfo,
|
||||
}
|
||||
|
||||
/* No luck, so prepare the expression for execution */
|
||||
ri_GeneratedExprs[i] = ExecPrepareExpr(expr, estate);
|
||||
ri_NumGeneratedNeeded++;
|
||||
if (attgenerated == ATTRIBUTE_GENERATED_STORED)
|
||||
{
|
||||
ri_GeneratedExprs[i] = ExecPrepareExpr(expr, estate);
|
||||
ri_NumGeneratedNeeded++;
|
||||
}
|
||||
|
||||
/* If UPDATE, mark column in resultRelInfo->ri_extraUpdatedCols */
|
||||
if (cmdtype == CMD_UPDATE)
|
||||
@ -478,6 +486,13 @@ ExecInitStoredGenerated(ResultRelInfo *resultRelInfo,
|
||||
}
|
||||
}
|
||||
|
||||
if (ri_NumGeneratedNeeded == 0)
|
||||
{
|
||||
/* didn't need it after all */
|
||||
pfree(ri_GeneratedExprs);
|
||||
ri_GeneratedExprs = NULL;
|
||||
}
|
||||
|
||||
/* Save in appropriate set of fields */
|
||||
if (cmdtype == CMD_UPDATE)
|
||||
{
|
||||
@ -486,6 +501,8 @@ ExecInitStoredGenerated(ResultRelInfo *resultRelInfo,
|
||||
|
||||
resultRelInfo->ri_GeneratedExprsU = ri_GeneratedExprs;
|
||||
resultRelInfo->ri_NumGeneratedNeededU = ri_NumGeneratedNeeded;
|
||||
|
||||
resultRelInfo->ri_extraUpdatedCols_valid = true;
|
||||
}
|
||||
else
|
||||
{
|
||||
@ -526,7 +543,7 @@ ExecComputeStoredGenerated(ResultRelInfo *resultRelInfo,
|
||||
if (cmdtype == CMD_UPDATE)
|
||||
{
|
||||
if (resultRelInfo->ri_GeneratedExprsU == NULL)
|
||||
ExecInitStoredGenerated(resultRelInfo, estate, cmdtype);
|
||||
ExecInitGenerated(resultRelInfo, estate, cmdtype);
|
||||
if (resultRelInfo->ri_NumGeneratedNeededU == 0)
|
||||
return;
|
||||
ri_GeneratedExprs = resultRelInfo->ri_GeneratedExprsU;
|
||||
@ -534,7 +551,7 @@ ExecComputeStoredGenerated(ResultRelInfo *resultRelInfo,
|
||||
else
|
||||
{
|
||||
if (resultRelInfo->ri_GeneratedExprsI == NULL)
|
||||
ExecInitStoredGenerated(resultRelInfo, estate, cmdtype);
|
||||
ExecInitGenerated(resultRelInfo, estate, cmdtype);
|
||||
/* Early exit is impossible given the prior Assert */
|
||||
Assert(resultRelInfo->ri_NumGeneratedNeededI > 0);
|
||||
ri_GeneratedExprs = resultRelInfo->ri_GeneratedExprsI;
|
||||
|
@ -636,7 +636,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
|
||||
%type <str> opt_existing_window_name
|
||||
%type <boolean> opt_if_not_exists
|
||||
%type <boolean> opt_unique_null_treatment
|
||||
%type <ival> generated_when override_kind
|
||||
%type <ival> generated_when override_kind opt_virtual_or_stored
|
||||
%type <partspec> PartitionSpec OptPartitionSpec
|
||||
%type <partelem> part_elem
|
||||
%type <list> part_params
|
||||
@ -784,7 +784,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
|
||||
UNLISTEN UNLOGGED UNTIL UPDATE USER USING
|
||||
|
||||
VACUUM VALID VALIDATE VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING
|
||||
VERBOSE VERSION_P VIEW VIEWS VOLATILE
|
||||
VERBOSE VERSION_P VIEW VIEWS VIRTUAL VOLATILE
|
||||
|
||||
WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
|
||||
|
||||
@ -3995,7 +3995,7 @@ ColConstraintElem:
|
||||
n->location = @1;
|
||||
$$ = (Node *) n;
|
||||
}
|
||||
| GENERATED generated_when AS '(' a_expr ')' STORED
|
||||
| GENERATED generated_when AS '(' a_expr ')' opt_virtual_or_stored
|
||||
{
|
||||
Constraint *n = makeNode(Constraint);
|
||||
|
||||
@ -4003,6 +4003,7 @@ ColConstraintElem:
|
||||
n->generated_when = $2;
|
||||
n->raw_expr = $5;
|
||||
n->cooked_expr = NULL;
|
||||
n->generated_kind = $7;
|
||||
n->location = @1;
|
||||
|
||||
/*
|
||||
@ -4050,6 +4051,12 @@ generated_when:
|
||||
| BY DEFAULT { $$ = ATTRIBUTE_IDENTITY_BY_DEFAULT; }
|
||||
;
|
||||
|
||||
opt_virtual_or_stored:
|
||||
STORED { $$ = ATTRIBUTE_GENERATED_STORED; }
|
||||
| VIRTUAL { $$ = ATTRIBUTE_GENERATED_VIRTUAL; }
|
||||
| /*EMPTY*/ { $$ = ATTRIBUTE_GENERATED_VIRTUAL; }
|
||||
;
|
||||
|
||||
/*
|
||||
* ConstraintAttr represents constraint attributes, which we parse as if
|
||||
* they were independent constraint clauses, in order to avoid shift/reduce
|
||||
@ -17990,6 +17997,7 @@ unreserved_keyword:
|
||||
| VERSION_P
|
||||
| VIEW
|
||||
| VIEWS
|
||||
| VIRTUAL
|
||||
| VOLATILE
|
||||
| WHITESPACE_P
|
||||
| WITHIN
|
||||
@ -18645,6 +18653,7 @@ bare_label_keyword:
|
||||
| VERSION_P
|
||||
| VIEW
|
||||
| VIEWS
|
||||
| VIRTUAL
|
||||
| VOLATILE
|
||||
| WHEN
|
||||
| WHITESPACE_P
|
||||
|
@ -712,7 +712,11 @@ scanNSItemForColumn(ParseState *pstate, ParseNamespaceItem *nsitem,
|
||||
colname),
|
||||
parser_errposition(pstate, location)));
|
||||
|
||||
/* In generated column, no system column is allowed except tableOid */
|
||||
/*
|
||||
* In generated column, no system column is allowed except tableOid.
|
||||
* (Required for stored generated, but we also do it for virtual generated
|
||||
* for now for consistency.)
|
||||
*/
|
||||
if (pstate->p_expr_kind == EXPR_KIND_GENERATED_COLUMN &&
|
||||
attnum < InvalidAttrNumber && attnum != TableOidAttributeNumber)
|
||||
ereport(ERROR,
|
||||
|
@ -889,7 +889,7 @@ transformColumnDefinition(CreateStmtContext *cxt, ColumnDef *column)
|
||||
column->colname, cxt->relation->relname),
|
||||
parser_errposition(cxt->pstate,
|
||||
constraint->location)));
|
||||
column->generated = ATTRIBUTE_GENERATED_STORED;
|
||||
column->generated = constraint->generated_kind;
|
||||
column->raw_default = constraint->raw_expr;
|
||||
Assert(constraint->cooked_expr == NULL);
|
||||
saw_generated = true;
|
||||
@ -988,6 +988,20 @@ transformColumnDefinition(CreateStmtContext *cxt, ColumnDef *column)
|
||||
column->colname, cxt->relation->relname),
|
||||
parser_errposition(cxt->pstate,
|
||||
constraint->location)));
|
||||
|
||||
/*
|
||||
* TODO: Straightforward not-null constraints won't work on virtual
|
||||
* generated columns, because there is no support for expanding the
|
||||
* column when the constraint is checked. Maybe we could convert the
|
||||
* not-null constraint into a full check constraint, so that the
|
||||
* generation expression can be expanded at check time.
|
||||
*/
|
||||
if (column->is_not_null && column->generated == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("not-null constraints are not supported on virtual generated columns"),
|
||||
parser_errposition(cxt->pstate,
|
||||
constraint->location)));
|
||||
}
|
||||
|
||||
/*
|
||||
|
@ -27,6 +27,7 @@
|
||||
#include "replication/logicalproto.h"
|
||||
#include "replication/origin.h"
|
||||
#include "replication/pgoutput.h"
|
||||
#include "rewrite/rewriteHandler.h"
|
||||
#include "utils/builtins.h"
|
||||
#include "utils/inval.h"
|
||||
#include "utils/lsyscache.h"
|
||||
@ -1010,7 +1011,7 @@ pgoutput_row_filter_init(PGOutputData *data, List *publications,
|
||||
continue;
|
||||
|
||||
foreach(lc, rfnodes[idx])
|
||||
filters = lappend(filters, stringToNode((char *) lfirst(lc)));
|
||||
filters = lappend(filters, expand_generated_columns_in_expr(stringToNode((char *) lfirst(lc)), relation, 1));
|
||||
|
||||
/* combine the row filter and cache the ExprState */
|
||||
rfnode = make_orclause(filters);
|
||||
|
@ -96,6 +96,8 @@ static List *matchLocks(CmdType event, Relation relation,
|
||||
int varno, Query *parsetree, bool *hasUpdate);
|
||||
static Query *fireRIRrules(Query *parsetree, List *activeRIRs);
|
||||
static Bitmapset *adjust_view_column_set(Bitmapset *cols, List *targetlist);
|
||||
static Node *expand_generated_columns_internal(Node *node, Relation rel, int rt_index,
|
||||
RangeTblEntry *rte, int result_relation);
|
||||
|
||||
|
||||
/*
|
||||
@ -986,7 +988,8 @@ rewriteTargetListIU(List *targetList,
|
||||
if (att_tup->attgenerated)
|
||||
{
|
||||
/*
|
||||
* stored generated column will be fixed in executor
|
||||
* virtual generated column stores a null value; stored generated
|
||||
* column will be fixed in executor
|
||||
*/
|
||||
new_tle = NULL;
|
||||
}
|
||||
@ -2187,6 +2190,10 @@ fireRIRrules(Query *parsetree, List *activeRIRs)
|
||||
* requires special recursion detection if the new quals have sublink
|
||||
* subqueries, and if we did it in the loop above query_tree_walker would
|
||||
* then recurse into those quals a second time.
|
||||
*
|
||||
* Finally, we expand any virtual generated columns. We do this after
|
||||
* each table's RLS policies are applied because the RLS policies might
|
||||
* also refer to the table's virtual generated columns.
|
||||
*/
|
||||
rt_index = 0;
|
||||
foreach(lc, parsetree->rtable)
|
||||
@ -2200,10 +2207,11 @@ fireRIRrules(Query *parsetree, List *activeRIRs)
|
||||
|
||||
++rt_index;
|
||||
|
||||
/* Only normal relations can have RLS policies */
|
||||
if (rte->rtekind != RTE_RELATION ||
|
||||
(rte->relkind != RELKIND_RELATION &&
|
||||
rte->relkind != RELKIND_PARTITIONED_TABLE))
|
||||
/*
|
||||
* Only normal relations can have RLS policies or virtual generated
|
||||
* columns.
|
||||
*/
|
||||
if (rte->rtekind != RTE_RELATION)
|
||||
continue;
|
||||
|
||||
rel = table_open(rte->relid, NoLock);
|
||||
@ -2292,6 +2300,16 @@ fireRIRrules(Query *parsetree, List *activeRIRs)
|
||||
if (hasSubLinks)
|
||||
parsetree->hasSubLinks = true;
|
||||
|
||||
/*
|
||||
* Expand any references to virtual generated columns of this table.
|
||||
* Note that subqueries in virtual generated column expressions are
|
||||
* not currently supported, so this cannot add any more sublinks.
|
||||
*/
|
||||
parsetree = (Query *)
|
||||
expand_generated_columns_internal((Node *) parsetree,
|
||||
rel, rt_index, rte,
|
||||
parsetree->resultRelation);
|
||||
|
||||
table_close(rel, NoLock);
|
||||
}
|
||||
|
||||
@ -4406,6 +4424,111 @@ RewriteQuery(Query *parsetree, List *rewrite_events, int orig_rt_length)
|
||||
}
|
||||
|
||||
|
||||
/*
|
||||
* Expand virtual generated columns
|
||||
*
|
||||
* If the table contains virtual generated columns, build a target list
|
||||
* containing the expanded expressions and use ReplaceVarsFromTargetList() to
|
||||
* do the replacements.
|
||||
*
|
||||
* Vars matching rt_index at the current query level are replaced by the
|
||||
* virtual generated column expressions from rel, if there are any.
|
||||
*
|
||||
* The caller must also provide rte, the RTE describing the target relation,
|
||||
* in order to handle any whole-row Vars referencing the target, and
|
||||
* result_relation, the index of the result relation, if this is part of an
|
||||
* INSERT/UPDATE/DELETE/MERGE query.
|
||||
*/
|
||||
static Node *
|
||||
expand_generated_columns_internal(Node *node, Relation rel, int rt_index,
|
||||
RangeTblEntry *rte, int result_relation)
|
||||
{
|
||||
TupleDesc tupdesc;
|
||||
|
||||
tupdesc = RelationGetDescr(rel);
|
||||
if (tupdesc->constr && tupdesc->constr->has_generated_virtual)
|
||||
{
|
||||
List *tlist = NIL;
|
||||
|
||||
for (int i = 0; i < tupdesc->natts; i++)
|
||||
{
|
||||
Form_pg_attribute attr = TupleDescAttr(tupdesc, i);
|
||||
|
||||
if (attr->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
{
|
||||
Node *defexpr;
|
||||
int attnum = i + 1;
|
||||
Oid attcollid;
|
||||
TargetEntry *te;
|
||||
|
||||
defexpr = build_column_default(rel, attnum);
|
||||
if (defexpr == NULL)
|
||||
elog(ERROR, "no generation expression found for column number %d of table \"%s\"",
|
||||
attnum, RelationGetRelationName(rel));
|
||||
|
||||
/*
|
||||
* If the column definition has a collation and it is
|
||||
* different from the collation of the generation expression,
|
||||
* put a COLLATE clause around the expression.
|
||||
*/
|
||||
attcollid = attr->attcollation;
|
||||
if (attcollid && attcollid != exprCollation(defexpr))
|
||||
{
|
||||
CollateExpr *ce = makeNode(CollateExpr);
|
||||
|
||||
ce->arg = (Expr *) defexpr;
|
||||
ce->collOid = attcollid;
|
||||
ce->location = -1;
|
||||
|
||||
defexpr = (Node *) ce;
|
||||
}
|
||||
|
||||
ChangeVarNodes(defexpr, 1, rt_index, 0);
|
||||
|
||||
te = makeTargetEntry((Expr *) defexpr, attnum, 0, false);
|
||||
tlist = lappend(tlist, te);
|
||||
}
|
||||
}
|
||||
|
||||
Assert(list_length(tlist) > 0);
|
||||
|
||||
node = ReplaceVarsFromTargetList(node, rt_index, 0, rte, tlist,
|
||||
result_relation,
|
||||
REPLACEVARS_CHANGE_VARNO, rt_index,
|
||||
NULL);
|
||||
}
|
||||
|
||||
return node;
|
||||
}
|
||||
|
||||
/*
|
||||
* Expand virtual generated columns in an expression
|
||||
*
|
||||
* This is for expressions that are not part of a query, such as default
|
||||
* expressions or index predicates. The rt_index is usually 1.
|
||||
*/
|
||||
Node *
|
||||
expand_generated_columns_in_expr(Node *node, Relation rel, int rt_index)
|
||||
{
|
||||
TupleDesc tupdesc = RelationGetDescr(rel);
|
||||
|
||||
if (tupdesc->constr && tupdesc->constr->has_generated_virtual)
|
||||
{
|
||||
RangeTblEntry *rte;
|
||||
|
||||
rte = makeNode(RangeTblEntry);
|
||||
/* eref needs to be set, but the actual name doesn't matter */
|
||||
rte->eref = makeAlias(RelationGetRelationName(rel), NIL);
|
||||
rte->rtekind = RTE_RELATION;
|
||||
rte->relid = RelationGetRelid(rel);
|
||||
|
||||
node = expand_generated_columns_internal(node, rel, rt_index, rte, 0);
|
||||
}
|
||||
|
||||
return node;
|
||||
}
|
||||
|
||||
|
||||
/*
|
||||
* QueryRewrite -
|
||||
* Primary entry point to the query rewriter.
|
||||
|
3
src/backend/utils/cache/relcache.c
vendored
3
src/backend/utils/cache/relcache.c
vendored
@ -592,6 +592,8 @@ RelationBuildTupleDesc(Relation relation)
|
||||
constr->has_not_null = true;
|
||||
if (attp->attgenerated == ATTRIBUTE_GENERATED_STORED)
|
||||
constr->has_generated_stored = true;
|
||||
if (attp->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
constr->has_generated_virtual = true;
|
||||
if (attp->atthasdef)
|
||||
ndef++;
|
||||
|
||||
@ -674,6 +676,7 @@ RelationBuildTupleDesc(Relation relation)
|
||||
*/
|
||||
if (constr->has_not_null ||
|
||||
constr->has_generated_stored ||
|
||||
constr->has_generated_virtual ||
|
||||
ndef > 0 ||
|
||||
attrmiss ||
|
||||
relation->rd_rel->relchecks > 0)
|
||||
|
@ -16190,6 +16190,9 @@ dumpTableSchema(Archive *fout, const TableInfo *tbinfo)
|
||||
if (tbinfo->attgenerated[j] == ATTRIBUTE_GENERATED_STORED)
|
||||
appendPQExpBuffer(q, " GENERATED ALWAYS AS (%s) STORED",
|
||||
tbinfo->attrdefs[j]->adef_expr);
|
||||
else if (tbinfo->attgenerated[j] == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
appendPQExpBuffer(q, " GENERATED ALWAYS AS (%s)",
|
||||
tbinfo->attrdefs[j]->adef_expr);
|
||||
else
|
||||
appendPQExpBuffer(q, " DEFAULT %s",
|
||||
tbinfo->attrdefs[j]->adef_expr);
|
||||
|
@ -3706,12 +3706,14 @@ my %tests = (
|
||||
create_order => 3,
|
||||
create_sql => 'CREATE TABLE dump_test.test_table_generated (
|
||||
col1 int primary key,
|
||||
col2 int generated always as (col1 * 2) stored
|
||||
col2 int generated always as (col1 * 2) stored,
|
||||
col3 int generated always as (col1 * 3) virtual
|
||||
);',
|
||||
regexp => qr/^
|
||||
\QCREATE TABLE dump_test.test_table_generated (\E\n
|
||||
\s+\Qcol1 integer NOT NULL,\E\n
|
||||
\s+\Qcol2 integer GENERATED ALWAYS AS ((col1 * 2)) STORED\E\n
|
||||
\s+\Qcol2 integer GENERATED ALWAYS AS ((col1 * 2)) STORED,\E\n
|
||||
\s+\Qcol3 integer GENERATED ALWAYS AS ((col1 * 3))\E\n
|
||||
\);
|
||||
/xms,
|
||||
like =>
|
||||
|
@ -2123,6 +2123,12 @@ describeOneTableDetails(const char *schemaname,
|
||||
PQgetvalue(res, i, attrdef_col));
|
||||
mustfree = true;
|
||||
}
|
||||
else if (generated[0] == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
{
|
||||
default_str = psprintf("generated always as (%s)",
|
||||
PQgetvalue(res, i, attrdef_col));
|
||||
mustfree = true;
|
||||
}
|
||||
else
|
||||
default_str = PQgetvalue(res, i, attrdef_col);
|
||||
|
||||
|
@ -44,6 +44,7 @@ typedef struct TupleConstr
|
||||
uint16 num_check;
|
||||
bool has_not_null;
|
||||
bool has_generated_stored;
|
||||
bool has_generated_virtual;
|
||||
} TupleConstr;
|
||||
|
||||
/*
|
||||
|
@ -57,6 +57,6 @@
|
||||
*/
|
||||
|
||||
/* yyyymmddN */
|
||||
#define CATALOG_VERSION_NO 202501282
|
||||
#define CATALOG_VERSION_NO 202502071
|
||||
|
||||
#endif
|
||||
|
@ -23,6 +23,7 @@
|
||||
#define CHKATYPE_ANYARRAY 0x01 /* allow ANYARRAY */
|
||||
#define CHKATYPE_ANYRECORD 0x02 /* allow RECORD and RECORD[] */
|
||||
#define CHKATYPE_IS_PARTKEY 0x04 /* attname is part key # not column */
|
||||
#define CHKATYPE_IS_VIRTUAL 0x08 /* is virtual generated column */
|
||||
|
||||
typedef struct RawColumnDefault
|
||||
{
|
||||
|
@ -225,6 +225,7 @@ MAKE_SYSCACHE(ATTNUM, pg_attribute_relid_attnum_index, 128);
|
||||
#define ATTRIBUTE_IDENTITY_BY_DEFAULT 'd'
|
||||
|
||||
#define ATTRIBUTE_GENERATED_STORED 's'
|
||||
#define ATTRIBUTE_GENERATED_VIRTUAL 'v'
|
||||
|
||||
#endif /* EXPOSE_TO_CLIENT_CODE */
|
||||
|
||||
|
@ -15,9 +15,9 @@
|
||||
|
||||
#include "nodes/execnodes.h"
|
||||
|
||||
extern void ExecInitStoredGenerated(ResultRelInfo *resultRelInfo,
|
||||
EState *estate,
|
||||
CmdType cmdtype);
|
||||
extern void ExecInitGenerated(ResultRelInfo *resultRelInfo,
|
||||
EState *estate,
|
||||
CmdType cmdtype);
|
||||
|
||||
extern void ExecComputeStoredGenerated(ResultRelInfo *resultRelInfo,
|
||||
EState *estate, TupleTableSlot *slot,
|
||||
|
@ -490,6 +490,8 @@ typedef struct ResultRelInfo
|
||||
|
||||
/* For UPDATE, attnums of generated columns to be computed */
|
||||
Bitmapset *ri_extraUpdatedCols;
|
||||
/* true if the above has been computed */
|
||||
bool ri_extraUpdatedCols_valid;
|
||||
|
||||
/* Projection to generate new tuple in an INSERT/UPDATE */
|
||||
ProjectionInfo *ri_projectNew;
|
||||
|
@ -2812,6 +2812,7 @@ typedef struct Constraint
|
||||
char *cooked_expr; /* CHECK or DEFAULT expression, as
|
||||
* nodeToString representation */
|
||||
char generated_when; /* ALWAYS or BY DEFAULT */
|
||||
char generated_kind; /* STORED or VIRTUAL */
|
||||
bool nulls_not_distinct; /* null treatment for UNIQUE constraints */
|
||||
List *keys; /* String nodes naming referenced key
|
||||
* column(s); for UNIQUE/PK/NOT NULL */
|
||||
|
@ -491,6 +491,7 @@ PG_KEYWORD("verbose", VERBOSE, TYPE_FUNC_NAME_KEYWORD, BARE_LABEL)
|
||||
PG_KEYWORD("version", VERSION_P, UNRESERVED_KEYWORD, BARE_LABEL)
|
||||
PG_KEYWORD("view", VIEW, UNRESERVED_KEYWORD, BARE_LABEL)
|
||||
PG_KEYWORD("views", VIEWS, UNRESERVED_KEYWORD, BARE_LABEL)
|
||||
PG_KEYWORD("virtual", VIRTUAL, UNRESERVED_KEYWORD, BARE_LABEL)
|
||||
PG_KEYWORD("volatile", VOLATILE, UNRESERVED_KEYWORD, BARE_LABEL)
|
||||
PG_KEYWORD("when", WHEN, RESERVED_KEYWORD, BARE_LABEL)
|
||||
PG_KEYWORD("where", WHERE, RESERVED_KEYWORD, AS_LABEL)
|
||||
|
@ -38,4 +38,6 @@ extern void error_view_not_updatable(Relation view,
|
||||
List *mergeActionList,
|
||||
const char *detail);
|
||||
|
||||
extern Node *expand_generated_columns_in_expr(Node *node, Relation rel, int rt_index);
|
||||
|
||||
#endif /* REWRITEHANDLER_H */
|
||||
|
@ -8,7 +8,8 @@ CREATE TABLE trigger_test (
|
||||
);
|
||||
CREATE TABLE trigger_test_generated (
|
||||
i int,
|
||||
j int GENERATED ALWAYS AS (i * 2) STORED
|
||||
j int GENERATED ALWAYS AS (i * 2) STORED,
|
||||
k int GENERATED ALWAYS AS (i * 3) VIRTUAL
|
||||
);
|
||||
CREATE OR REPLACE FUNCTION trigger_data() RETURNS trigger LANGUAGE plperl AS $$
|
||||
|
||||
@ -386,7 +387,7 @@ INSERT INTO trigger_test_generated (i) VALUES (1);
|
||||
ERROR: cannot set generated column "j"
|
||||
CONTEXT: PL/Perl function "generated_test_func1"
|
||||
SELECT * FROM trigger_test_generated;
|
||||
i | j
|
||||
---+---
|
||||
i | j | k
|
||||
---+---+---
|
||||
(0 rows)
|
||||
|
||||
|
@ -3047,6 +3047,9 @@ plperl_hash_from_tuple(HeapTuple tuple, TupleDesc tupdesc, bool include_generate
|
||||
/* don't include unless requested */
|
||||
if (!include_generated)
|
||||
continue;
|
||||
/* never include virtual columns */
|
||||
if (att->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
continue;
|
||||
}
|
||||
|
||||
attname = NameStr(att->attname);
|
||||
|
@ -10,7 +10,8 @@ CREATE TABLE trigger_test (
|
||||
|
||||
CREATE TABLE trigger_test_generated (
|
||||
i int,
|
||||
j int GENERATED ALWAYS AS (i * 2) STORED
|
||||
j int GENERATED ALWAYS AS (i * 2) STORED,
|
||||
k int GENERATED ALWAYS AS (i * 3) VIRTUAL
|
||||
);
|
||||
|
||||
CREATE OR REPLACE FUNCTION trigger_data() RETURNS trigger LANGUAGE plperl AS $$
|
||||
|
@ -69,7 +69,8 @@ CREATE TABLE trigger_test
|
||||
(i int, v text );
|
||||
CREATE TABLE trigger_test_generated (
|
||||
i int,
|
||||
j int GENERATED ALWAYS AS (i * 2) STORED
|
||||
j int GENERATED ALWAYS AS (i * 2) STORED,
|
||||
k int GENERATED ALWAYS AS (i * 3) VIRTUAL
|
||||
);
|
||||
CREATE FUNCTION trigger_data() RETURNS trigger LANGUAGE plpython3u AS $$
|
||||
|
||||
@ -614,8 +615,8 @@ ERROR: cannot set generated column "j"
|
||||
CONTEXT: while modifying trigger row
|
||||
PL/Python function "generated_test_func1"
|
||||
SELECT * FROM trigger_test_generated;
|
||||
i | j
|
||||
---+---
|
||||
i | j | k
|
||||
---+---+---
|
||||
(0 rows)
|
||||
|
||||
-- recursive call of a trigger mustn't corrupt TD (bug #18456)
|
||||
|
@ -844,6 +844,9 @@ PLyDict_FromTuple(PLyDatumToOb *arg, HeapTuple tuple, TupleDesc desc, bool inclu
|
||||
/* don't include unless requested */
|
||||
if (!include_generated)
|
||||
continue;
|
||||
/* never include virtual columns */
|
||||
if (attr->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
continue;
|
||||
}
|
||||
|
||||
key = NameStr(attr->attname);
|
||||
|
@ -69,7 +69,8 @@ CREATE TABLE trigger_test
|
||||
|
||||
CREATE TABLE trigger_test_generated (
|
||||
i int,
|
||||
j int GENERATED ALWAYS AS (i * 2) STORED
|
||||
j int GENERATED ALWAYS AS (i * 2) STORED,
|
||||
k int GENERATED ALWAYS AS (i * 3) VIRTUAL
|
||||
);
|
||||
|
||||
CREATE FUNCTION trigger_data() RETURNS trigger LANGUAGE plpython3u AS $$
|
||||
|
@ -63,7 +63,8 @@ CREATE TABLE trigger_test (
|
||||
ALTER TABLE trigger_test DROP dropme;
|
||||
CREATE TABLE trigger_test_generated (
|
||||
i int,
|
||||
j int GENERATED ALWAYS AS (i * 2) STORED
|
||||
j int GENERATED ALWAYS AS (i * 2) STORED,
|
||||
k int GENERATED ALWAYS AS (i * 3) VIRTUAL
|
||||
);
|
||||
CREATE VIEW trigger_test_view AS SELECT i, v FROM trigger_test;
|
||||
CREATE FUNCTION trigger_data() returns trigger language pltcl as $_$
|
||||
@ -647,7 +648,7 @@ NOTICE: OLD: {}
|
||||
NOTICE: TG_level: ROW
|
||||
NOTICE: TG_name: show_trigger_data_trig_before
|
||||
NOTICE: TG_op: INSERT
|
||||
NOTICE: TG_relatts: {{} i j}
|
||||
NOTICE: TG_relatts: {{} i j k}
|
||||
NOTICE: TG_relid: bogus:12345
|
||||
NOTICE: TG_table_name: trigger_test_generated
|
||||
NOTICE: TG_table_schema: public
|
||||
@ -658,7 +659,7 @@ NOTICE: OLD: {}
|
||||
NOTICE: TG_level: ROW
|
||||
NOTICE: TG_name: show_trigger_data_trig_after
|
||||
NOTICE: TG_op: INSERT
|
||||
NOTICE: TG_relatts: {{} i j}
|
||||
NOTICE: TG_relatts: {{} i j k}
|
||||
NOTICE: TG_relid: bogus:12345
|
||||
NOTICE: TG_table_name: trigger_test_generated
|
||||
NOTICE: TG_table_schema: public
|
||||
@ -670,7 +671,7 @@ NOTICE: OLD: {i: 1, j: 2}
|
||||
NOTICE: TG_level: ROW
|
||||
NOTICE: TG_name: show_trigger_data_trig_before
|
||||
NOTICE: TG_op: UPDATE
|
||||
NOTICE: TG_relatts: {{} i j}
|
||||
NOTICE: TG_relatts: {{} i j k}
|
||||
NOTICE: TG_relid: bogus:12345
|
||||
NOTICE: TG_table_name: trigger_test_generated
|
||||
NOTICE: TG_table_schema: public
|
||||
@ -681,7 +682,7 @@ NOTICE: OLD: {i: 1, j: 2}
|
||||
NOTICE: TG_level: ROW
|
||||
NOTICE: TG_name: show_trigger_data_trig_after
|
||||
NOTICE: TG_op: UPDATE
|
||||
NOTICE: TG_relatts: {{} i j}
|
||||
NOTICE: TG_relatts: {{} i j k}
|
||||
NOTICE: TG_relid: bogus:12345
|
||||
NOTICE: TG_table_name: trigger_test_generated
|
||||
NOTICE: TG_table_schema: public
|
||||
@ -693,7 +694,7 @@ NOTICE: OLD: {i: 11, j: 22}
|
||||
NOTICE: TG_level: ROW
|
||||
NOTICE: TG_name: show_trigger_data_trig_before
|
||||
NOTICE: TG_op: DELETE
|
||||
NOTICE: TG_relatts: {{} i j}
|
||||
NOTICE: TG_relatts: {{} i j k}
|
||||
NOTICE: TG_relid: bogus:12345
|
||||
NOTICE: TG_table_name: trigger_test_generated
|
||||
NOTICE: TG_table_schema: public
|
||||
@ -704,7 +705,7 @@ NOTICE: OLD: {i: 11, j: 22}
|
||||
NOTICE: TG_level: ROW
|
||||
NOTICE: TG_name: show_trigger_data_trig_after
|
||||
NOTICE: TG_op: DELETE
|
||||
NOTICE: TG_relatts: {{} i j}
|
||||
NOTICE: TG_relatts: {{} i j k}
|
||||
NOTICE: TG_relid: bogus:12345
|
||||
NOTICE: TG_table_name: trigger_test_generated
|
||||
NOTICE: TG_table_schema: public
|
||||
@ -882,7 +883,7 @@ TRUNCATE trigger_test_generated;
|
||||
INSERT INTO trigger_test_generated (i) VALUES (1);
|
||||
ERROR: cannot set generated column "j"
|
||||
SELECT * FROM trigger_test_generated;
|
||||
i | j
|
||||
---+---
|
||||
i | j | k
|
||||
---+---+---
|
||||
(0 rows)
|
||||
|
||||
|
@ -3206,6 +3206,9 @@ pltcl_build_tuple_argument(HeapTuple tuple, TupleDesc tupdesc, bool include_gene
|
||||
/* don't include unless requested */
|
||||
if (!include_generated)
|
||||
continue;
|
||||
/* never include virtual columns */
|
||||
if (att->attgenerated == ATTRIBUTE_GENERATED_VIRTUAL)
|
||||
continue;
|
||||
}
|
||||
|
||||
/************************************************************
|
||||
|
@ -73,7 +73,8 @@ ALTER TABLE trigger_test DROP dropme;
|
||||
|
||||
CREATE TABLE trigger_test_generated (
|
||||
i int,
|
||||
j int GENERATED ALWAYS AS (i * 2) STORED
|
||||
j int GENERATED ALWAYS AS (i * 2) STORED,
|
||||
k int GENERATED ALWAYS AS (i * 3) VIRTUAL
|
||||
);
|
||||
|
||||
CREATE VIEW trigger_test_view AS SELECT i, v FROM trigger_test;
|
||||
|
@ -2555,6 +2555,26 @@ DROP TABLE pagg_tab6;
|
||||
RESET enable_partitionwise_aggregate;
|
||||
RESET max_parallel_workers_per_gather;
|
||||
RESET enable_incremental_sort;
|
||||
-- virtual generated columns
|
||||
CREATE TABLE t5 (
|
||||
a int,
|
||||
b text collate "C",
|
||||
c text collate "C" GENERATED ALWAYS AS (b COLLATE case_insensitive)
|
||||
);
|
||||
INSERT INTO t5 (a, b) values (1, 'D1'), (2, 'D2'), (3, 'd1');
|
||||
-- Collation of c should be the one defined for the column ("C"), not
|
||||
-- the one of the generation expression. (Note that we cannot just
|
||||
-- test with, say, using COLLATION FOR, because the collation of
|
||||
-- function calls is already determined in the parser before
|
||||
-- rewriting.)
|
||||
SELECT * FROM t5 ORDER BY c ASC, a ASC;
|
||||
a | b | c
|
||||
---+----+----
|
||||
1 | D1 | D1
|
||||
2 | D2 | D2
|
||||
3 | d1 | d1
|
||||
(3 rows)
|
||||
|
||||
-- cleanup
|
||||
RESET search_path;
|
||||
SET client_min_messages TO warning;
|
||||
|
@ -113,19 +113,20 @@ SELECT * FROM test_like_id_3; -- identity was copied and applied
|
||||
(1 row)
|
||||
|
||||
DROP TABLE test_like_id_1, test_like_id_2, test_like_id_3;
|
||||
CREATE TABLE test_like_gen_1 (a int, b int GENERATED ALWAYS AS (a * 2) STORED);
|
||||
CREATE TABLE test_like_gen_1 (a int, b int GENERATED ALWAYS AS (a * 2) STORED, c int GENERATED ALWAYS AS (a * 3) VIRTUAL);
|
||||
\d test_like_gen_1
|
||||
Table "public.test_like_gen_1"
|
||||
Column | Type | Collation | Nullable | Default
|
||||
--------+---------+-----------+----------+------------------------------------
|
||||
a | integer | | |
|
||||
b | integer | | | generated always as (a * 2) stored
|
||||
c | integer | | | generated always as (a * 3)
|
||||
|
||||
INSERT INTO test_like_gen_1 (a) VALUES (1);
|
||||
SELECT * FROM test_like_gen_1;
|
||||
a | b
|
||||
---+---
|
||||
1 | 2
|
||||
a | b | c
|
||||
---+---+---
|
||||
1 | 2 | 3
|
||||
(1 row)
|
||||
|
||||
CREATE TABLE test_like_gen_2 (LIKE test_like_gen_1);
|
||||
@ -135,12 +136,13 @@ CREATE TABLE test_like_gen_2 (LIKE test_like_gen_1);
|
||||
--------+---------+-----------+----------+---------
|
||||
a | integer | | |
|
||||
b | integer | | |
|
||||
c | integer | | |
|
||||
|
||||
INSERT INTO test_like_gen_2 (a) VALUES (1);
|
||||
SELECT * FROM test_like_gen_2;
|
||||
a | b
|
||||
---+---
|
||||
1 |
|
||||
a | b | c
|
||||
---+---+---
|
||||
1 | |
|
||||
(1 row)
|
||||
|
||||
CREATE TABLE test_like_gen_3 (LIKE test_like_gen_1 INCLUDING GENERATED);
|
||||
@ -150,12 +152,13 @@ CREATE TABLE test_like_gen_3 (LIKE test_like_gen_1 INCLUDING GENERATED);
|
||||
--------+---------+-----------+----------+------------------------------------
|
||||
a | integer | | |
|
||||
b | integer | | | generated always as (a * 2) stored
|
||||
c | integer | | | generated always as (a * 3)
|
||||
|
||||
INSERT INTO test_like_gen_3 (a) VALUES (1);
|
||||
SELECT * FROM test_like_gen_3;
|
||||
a | b
|
||||
---+---
|
||||
1 | 2
|
||||
a | b | c
|
||||
---+---+---
|
||||
1 | 2 | 3
|
||||
(1 row)
|
||||
|
||||
DROP TABLE test_like_gen_1, test_like_gen_2, test_like_gen_3;
|
||||
|
@ -58,6 +58,18 @@ ALTER TABLE has_volatile ADD col2 int DEFAULT 1;
|
||||
ALTER TABLE has_volatile ADD col3 timestamptz DEFAULT current_timestamp;
|
||||
ALTER TABLE has_volatile ADD col4 int DEFAULT (random() * 10000)::int;
|
||||
NOTICE: rewriting table has_volatile for reason 2
|
||||
-- virtual generated columns don't need a rewrite
|
||||
ALTER TABLE has_volatile ADD col5 int GENERATED ALWAYS AS (tableoid::int + col2) VIRTUAL;
|
||||
ALTER TABLE has_volatile ALTER COLUMN col5 TYPE float8;
|
||||
ALTER TABLE has_volatile ALTER COLUMN col5 TYPE numeric;
|
||||
ALTER TABLE has_volatile ALTER COLUMN col5 TYPE numeric;
|
||||
-- here, we do need a rewrite
|
||||
ALTER TABLE has_volatile ALTER COLUMN col1 SET DATA TYPE float8,
|
||||
ADD COLUMN col6 float8 GENERATED ALWAYS AS (col1 * 4) VIRTUAL;
|
||||
NOTICE: rewriting table has_volatile for reason 4
|
||||
-- stored generated columns need a rewrite
|
||||
ALTER TABLE has_volatile ADD col7 int GENERATED ALWAYS AS (55) stored;
|
||||
NOTICE: rewriting table has_volatile for reason 2
|
||||
-- Test a large sample of different datatypes
|
||||
CREATE TABLE T(pk INT NOT NULL PRIMARY KEY, c_int INT DEFAULT 1);
|
||||
SELECT set('t');
|
||||
|
@ -1,3 +1,4 @@
|
||||
-- keep these tests aligned with generated_virtual.sql
|
||||
CREATE SCHEMA generated_stored_tests;
|
||||
GRANT USAGE ON SCHEMA generated_stored_tests TO PUBLIC;
|
||||
SET search_path = generated_stored_tests;
|
||||
@ -357,6 +358,10 @@ ERROR: column "b" inherits from generated column but specifies default
|
||||
CREATE TABLE gtestx (x int, b int GENERATED ALWAYS AS IDENTITY) INHERITS (gtest1); -- error
|
||||
NOTICE: merging column "b" with inherited definition
|
||||
ERROR: column "b" inherits from generated column but specifies identity
|
||||
CREATE TABLE gtestx (x int, b int GENERATED ALWAYS AS (a * 22) VIRTUAL) INHERITS (gtest1); -- error
|
||||
NOTICE: merging column "b" with inherited definition
|
||||
ERROR: column "b" inherits from generated column of different kind
|
||||
DETAIL: Parent column is STORED, child column is VIRTUAL.
|
||||
CREATE TABLE gtestx (x int, b int GENERATED ALWAYS AS (a * 22) STORED) INHERITS (gtest1); -- ok, overrides parent
|
||||
NOTICE: merging column "b" with inherited definition
|
||||
\d+ gtestx
|
||||
@ -868,6 +873,11 @@ CREATE TABLE gtest_child3 PARTITION OF gtest_parent (
|
||||
f3 WITH OPTIONS GENERATED ALWAYS AS IDENTITY -- error
|
||||
) FOR VALUES FROM ('2016-09-01') TO ('2016-10-01');
|
||||
ERROR: identity columns are not supported on partitions
|
||||
CREATE TABLE gtest_child3 PARTITION OF gtest_parent (
|
||||
f3 GENERATED ALWAYS AS (f2 * 2) VIRTUAL -- error
|
||||
) FOR VALUES FROM ('2016-09-01') TO ('2016-10-01');
|
||||
ERROR: column "f3" inherits from generated column of different kind
|
||||
DETAIL: Parent column is STORED, child column is VIRTUAL.
|
||||
CREATE TABLE gtest_child3 (f1 date NOT NULL, f2 bigint, f3 bigint);
|
||||
ALTER TABLE gtest_parent ATTACH PARTITION gtest_child3 FOR VALUES FROM ('2016-09-01') TO ('2016-10-01'); -- error
|
||||
ERROR: column "f3" in child table must be a generated column
|
||||
@ -881,6 +891,11 @@ ALTER TABLE gtest_parent ATTACH PARTITION gtest_child3 FOR VALUES FROM ('2016-09
|
||||
ERROR: table "gtest_child3" being attached contains an identity column "f3"
|
||||
DETAIL: The new partition may not contain an identity column.
|
||||
DROP TABLE gtest_child3;
|
||||
CREATE TABLE gtest_child3 (f1 date NOT NULL, f2 bigint, f3 bigint GENERATED ALWAYS AS (f2 * 33) VIRTUAL);
|
||||
ALTER TABLE gtest_parent ATTACH PARTITION gtest_child3 FOR VALUES FROM ('2016-09-01') TO ('2016-10-01'); -- error
|
||||
ERROR: column "f3" inherits from generated column of different kind
|
||||
DETAIL: Parent column is STORED, child column is VIRTUAL.
|
||||
DROP TABLE gtest_child3;
|
||||
CREATE TABLE gtest_child3 (f1 date NOT NULL, f2 bigint, f3 bigint GENERATED ALWAYS AS (f2 * 33) STORED);
|
||||
ALTER TABLE gtest_parent ATTACH PARTITION gtest_child3 FOR VALUES FROM ('2016-09-01') TO ('2016-10-01');
|
||||
\d gtest_child
|
||||
@ -1188,9 +1203,9 @@ SELECT * FROM gtest29;
|
||||
ALTER TABLE gtest29 ALTER COLUMN a SET EXPRESSION AS (a * 3); -- error
|
||||
ERROR: column "a" of relation "gtest29" is not a generated column
|
||||
ALTER TABLE gtest29 ALTER COLUMN a DROP EXPRESSION; -- error
|
||||
ERROR: column "a" of relation "gtest29" is not a stored generated column
|
||||
ERROR: column "a" of relation "gtest29" is not a generated column
|
||||
ALTER TABLE gtest29 ALTER COLUMN a DROP EXPRESSION IF EXISTS; -- notice
|
||||
NOTICE: column "a" of relation "gtest29" is not a stored generated column, skipping
|
||||
NOTICE: column "a" of relation "gtest29" is not a generated column, skipping
|
||||
-- Change the expression
|
||||
ALTER TABLE gtest29 ALTER COLUMN b SET EXPRESSION AS (a * 3);
|
||||
SELECT * FROM gtest29;
|
||||
@ -1471,7 +1486,7 @@ CREATE TABLE gtest28b (LIKE gtest28a INCLUDING GENERATED);
|
||||
x | integer | | | generated always as (b * 2) stored
|
||||
|
||||
-- sanity check of system catalog
|
||||
SELECT attrelid, attname, attgenerated FROM pg_attribute WHERE attgenerated NOT IN ('', 's');
|
||||
SELECT attrelid, attname, attgenerated FROM pg_attribute WHERE attgenerated NOT IN ('', 's', 'v');
|
||||
attrelid | attname | attgenerated
|
||||
----------+---------+--------------
|
||||
(0 rows)
|
||||
|
1400
src/test/regress/expected/generated_virtual.out
Normal file
1400
src/test/regress/expected/generated_virtual.out
Normal file
File diff suppressed because it is too large
Load Diff
@ -442,7 +442,7 @@ LINE 1: ...ICATION testpub6 FOR TABLE testpub_rf_tbl3 WHERE (e =#> 27);
|
||||
^
|
||||
DETAIL: User-defined operators are not allowed.
|
||||
-- fail - user-defined functions are not allowed
|
||||
CREATE FUNCTION testpub_rf_func2() RETURNS integer AS $$ BEGIN RETURN 123; END; $$ LANGUAGE plpgsql;
|
||||
CREATE FUNCTION testpub_rf_func2() RETURNS integer IMMUTABLE AS $$ BEGIN RETURN 123; END; $$ LANGUAGE plpgsql;
|
||||
ALTER PUBLICATION testpub5 ADD TABLE testpub_rf_tbl1 WHERE (a >= testpub_rf_func2());
|
||||
ERROR: invalid publication WHERE expression
|
||||
LINE 1: ...ON testpub5 ADD TABLE testpub_rf_tbl1 WHERE (a >= testpub_rf...
|
||||
@ -523,17 +523,33 @@ Tables:
|
||||
Tables from schemas:
|
||||
"testpub_rf_schema2"
|
||||
|
||||
-- fail - virtual generated column uses user-defined function
|
||||
CREATE TABLE testpub_rf_tbl6 (id int PRIMARY KEY, x int, y int GENERATED ALWAYS AS (x * testpub_rf_func2()) VIRTUAL);
|
||||
CREATE PUBLICATION testpub7 FOR TABLE testpub_rf_tbl6 WHERE (y > 100);
|
||||
ERROR: invalid publication WHERE expression
|
||||
DETAIL: User-defined or built-in mutable functions are not allowed.
|
||||
-- test that SET EXPRESSION is rejected, because it could affect a row filter
|
||||
SET client_min_messages = 'ERROR';
|
||||
CREATE TABLE testpub_rf_tbl7 (id int PRIMARY KEY, x int, y int GENERATED ALWAYS AS (x * 111) VIRTUAL);
|
||||
CREATE PUBLICATION testpub8 FOR TABLE testpub_rf_tbl7 WHERE (y > 100);
|
||||
ALTER TABLE testpub_rf_tbl7 ALTER COLUMN y SET EXPRESSION AS (x * testpub_rf_func2());
|
||||
ERROR: ALTER TABLE / SET EXPRESSION is not supported for virtual generated columns on tables that are part of a publication
|
||||
DETAIL: Column "y" of relation "testpub_rf_tbl7" is a virtual generated column.
|
||||
RESET client_min_messages;
|
||||
DROP TABLE testpub_rf_tbl1;
|
||||
DROP TABLE testpub_rf_tbl2;
|
||||
DROP TABLE testpub_rf_tbl3;
|
||||
DROP TABLE testpub_rf_tbl4;
|
||||
DROP TABLE testpub_rf_tbl5;
|
||||
DROP TABLE testpub_rf_tbl6;
|
||||
DROP TABLE testpub_rf_schema1.testpub_rf_tbl5;
|
||||
DROP TABLE testpub_rf_schema2.testpub_rf_tbl6;
|
||||
DROP SCHEMA testpub_rf_schema1;
|
||||
DROP SCHEMA testpub_rf_schema2;
|
||||
DROP PUBLICATION testpub5;
|
||||
DROP PUBLICATION testpub6;
|
||||
DROP PUBLICATION testpub8;
|
||||
DROP TABLE testpub_rf_tbl7;
|
||||
DROP OPERATOR =#>(integer, integer);
|
||||
DROP FUNCTION testpub_rf_func1(integer, integer);
|
||||
DROP FUNCTION testpub_rf_func2();
|
||||
@ -675,6 +691,7 @@ DROP TABLE rf_tbl_abcd_part_pk;
|
||||
-- ======================================================
|
||||
-- Tests with generated column
|
||||
SET client_min_messages = 'ERROR';
|
||||
-- stored
|
||||
CREATE TABLE testpub_gencol (a INT, b INT GENERATED ALWAYS AS (a + 1) STORED NOT NULL);
|
||||
CREATE UNIQUE INDEX testpub_gencol_idx ON testpub_gencol (b);
|
||||
ALTER TABLE testpub_gencol REPLICA IDENTITY USING index testpub_gencol_idx;
|
||||
@ -696,6 +713,23 @@ CREATE PUBLICATION pub_gencol FOR TABLE testpub_gencol with (publish_generated_c
|
||||
UPDATE testpub_gencol SET a = 100 WHERE a = 1;
|
||||
DROP PUBLICATION pub_gencol;
|
||||
DROP TABLE testpub_gencol;
|
||||
-- virtual
|
||||
CREATE TABLE testpub_gencol (a INT, b INT GENERATED ALWAYS AS (a + 1) VIRTUAL);
|
||||
CREATE PUBLICATION pub_gencol FOR TABLE testpub_gencol;
|
||||
-- error - generated column "b" must be published explicitly as it is
|
||||
-- part of the REPLICA IDENTITY.
|
||||
ALTER TABLE testpub_gencol REPLICA IDENTITY FULL;
|
||||
UPDATE testpub_gencol SET a = 100 WHERE a = 1;
|
||||
ERROR: cannot update table "testpub_gencol"
|
||||
DETAIL: Replica identity must not contain unpublished generated columns.
|
||||
DROP PUBLICATION pub_gencol;
|
||||
-- error - "stored" setting does not affect virtual column
|
||||
CREATE PUBLICATION pub_gencol FOR TABLE testpub_gencol with (publish_generated_columns = stored);
|
||||
UPDATE testpub_gencol SET a = 100 WHERE a = 1;
|
||||
ERROR: cannot update table "testpub_gencol"
|
||||
DETAIL: Replica identity must not contain unpublished generated columns.
|
||||
DROP PUBLICATION pub_gencol;
|
||||
DROP TABLE testpub_gencol;
|
||||
RESET client_min_messages;
|
||||
-- ======================================================
|
||||
-- fail - duplicate tables are not allowed if that table has any column lists
|
||||
@ -711,7 +745,9 @@ CREATE PUBLICATION testpub_fortable FOR TABLE testpub_tbl1;
|
||||
CREATE PUBLICATION testpub_fortable_insert WITH (publish = 'insert');
|
||||
RESET client_min_messages;
|
||||
CREATE TABLE testpub_tbl5 (a int PRIMARY KEY, b text, c text,
|
||||
d int generated always as (a + length(b)) stored);
|
||||
d int generated always as (a + length(b)) stored,
|
||||
e int generated always as (a + length(b)) virtual
|
||||
);
|
||||
-- error: column "x" does not exist
|
||||
ALTER PUBLICATION testpub_fortable ADD TABLE testpub_tbl5 (a, x);
|
||||
ERROR: column "x" of relation "testpub_tbl5" does not exist
|
||||
@ -748,9 +784,12 @@ UPDATE testpub_tbl5 SET a = 1;
|
||||
ERROR: cannot update table "testpub_tbl5"
|
||||
DETAIL: Column list used by the publication does not cover the replica identity.
|
||||
ALTER PUBLICATION testpub_fortable DROP TABLE testpub_tbl5;
|
||||
-- ok: generated column "d" can be in the list too
|
||||
-- ok: stored generated column "d" can be in the list too
|
||||
ALTER PUBLICATION testpub_fortable ADD TABLE testpub_tbl5 (a, d);
|
||||
ALTER PUBLICATION testpub_fortable DROP TABLE testpub_tbl5;
|
||||
-- error: virtual generated column "e" can't be in list
|
||||
ALTER PUBLICATION testpub_fortable ADD TABLE testpub_tbl5 (a, e);
|
||||
ERROR: cannot use virtual generated column "e" in publication column list
|
||||
-- error: change the replica identity to "b", and column list to (a, c)
|
||||
-- then update fails, because (a, c) does not cover replica identity
|
||||
ALTER TABLE testpub_tbl5 REPLICA IDENTITY USING INDEX testpub_tbl5_b_key;
|
||||
|
@ -4379,6 +4379,35 @@ ERROR: new row violates row-level security policy for table "r1"
|
||||
INSERT INTO r1 VALUES (10)
|
||||
ON CONFLICT ON CONSTRAINT r1_pkey DO UPDATE SET a = 30;
|
||||
ERROR: new row violates row-level security policy for table "r1"
|
||||
DROP TABLE r1;
|
||||
--
|
||||
-- Test policies using virtual generated columns
|
||||
--
|
||||
SET SESSION AUTHORIZATION regress_rls_alice;
|
||||
SET row_security = on;
|
||||
CREATE TABLE r1 (a int, b int GENERATED ALWAYS AS (a * 10) VIRTUAL);
|
||||
ALTER TABLE r1 ADD c int GENERATED ALWAYS AS (a * 100) VIRTUAL;
|
||||
INSERT INTO r1 VALUES (1), (2), (4);
|
||||
CREATE POLICY p0 ON r1 USING (b * 10 = c);
|
||||
CREATE POLICY p1 ON r1 AS RESTRICTIVE USING (b > 10);
|
||||
CREATE POLICY p2 ON r1 AS RESTRICTIVE USING ((SELECT c) < 400);
|
||||
ALTER TABLE r1 ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE r1 FORCE ROW LEVEL SECURITY;
|
||||
-- Should fail p1
|
||||
INSERT INTO r1 VALUES (0);
|
||||
ERROR: new row violates row-level security policy "p1" for table "r1"
|
||||
-- Should fail p2
|
||||
INSERT INTO r1 VALUES (4);
|
||||
ERROR: new row violates row-level security policy "p2" for table "r1"
|
||||
-- OK
|
||||
INSERT INTO r1 VALUES (3);
|
||||
SELECT * FROM r1;
|
||||
a | b | c
|
||||
---+----+-----
|
||||
2 | 20 | 200
|
||||
3 | 30 | 300
|
||||
(2 rows)
|
||||
|
||||
DROP TABLE r1;
|
||||
-- Check dependency handling
|
||||
RESET SESSION AUTHORIZATION;
|
||||
|
@ -66,6 +66,29 @@ ERROR: syntax error at or near ","
|
||||
LINE 1: CREATE STATISTICS tst ON (x, y) FROM ext_stats_test;
|
||||
^
|
||||
DROP TABLE ext_stats_test;
|
||||
-- statistics on virtual generated column not allowed
|
||||
CREATE TABLE ext_stats_test1 (x int, y int, z int GENERATED ALWAYS AS (x+y) VIRTUAL, w xid);
|
||||
CREATE STATISTICS tst on z from ext_stats_test1;
|
||||
ERROR: statistics creation on virtual generated columns is not supported
|
||||
CREATE STATISTICS tst on (z) from ext_stats_test1;
|
||||
ERROR: statistics creation on virtual generated columns is not supported
|
||||
CREATE STATISTICS tst on (z+1) from ext_stats_test1;
|
||||
ERROR: statistics creation on virtual generated columns is not supported
|
||||
CREATE STATISTICS tst (ndistinct) ON z from ext_stats_test1;
|
||||
ERROR: statistics creation on virtual generated columns is not supported
|
||||
-- statistics on system column not allowed
|
||||
CREATE STATISTICS tst on tableoid from ext_stats_test1;
|
||||
ERROR: statistics creation on system columns is not supported
|
||||
CREATE STATISTICS tst on (tableoid) from ext_stats_test1;
|
||||
ERROR: statistics creation on system columns is not supported
|
||||
CREATE STATISTICS tst on (tableoid::int+1) from ext_stats_test1;
|
||||
ERROR: statistics creation on system columns is not supported
|
||||
CREATE STATISTICS tst (ndistinct) ON xmin from ext_stats_test1;
|
||||
ERROR: statistics creation on system columns is not supported
|
||||
-- statistics without a less-than operator not supported
|
||||
CREATE STATISTICS tst (ndistinct) ON w from ext_stats_test1;
|
||||
ERROR: column "w" cannot be used in statistics because its type xid has no default btree operator class
|
||||
DROP TABLE ext_stats_test1;
|
||||
-- Ensure stats are dropped sanely, and test IF NOT EXISTS while at it
|
||||
CREATE TABLE ab1 (a INTEGER, b INTEGER, c INTEGER);
|
||||
CREATE STATISTICS IF NOT EXISTS ab1_a_b_stats ON a, b FROM ab1;
|
||||
|
@ -78,7 +78,7 @@ test: brin_bloom brin_multi
|
||||
# psql depends on create_am
|
||||
# amutils depends on geometry, create_index_spgist, hash_index, brin
|
||||
# ----------
|
||||
test: create_table_like alter_generic alter_operator misc async dbsize merge misc_functions sysviews tsrf tid tidscan tidrangescan collate.utf8 collate.icu.utf8 incremental_sort create_role without_overlaps
|
||||
test: create_table_like alter_generic alter_operator misc async dbsize merge misc_functions sysviews tsrf tid tidscan tidrangescan collate.utf8 collate.icu.utf8 incremental_sort create_role without_overlaps generated_virtual
|
||||
|
||||
# collate.linux.utf8 and collate.icu.utf8 tests cannot be run in parallel with each other
|
||||
test: rules psql psql_crosstab amutils stats_ext collate.linux.utf8 collate.windows.win1252
|
||||
|
@ -955,6 +955,21 @@ RESET enable_partitionwise_aggregate;
|
||||
RESET max_parallel_workers_per_gather;
|
||||
RESET enable_incremental_sort;
|
||||
|
||||
-- virtual generated columns
|
||||
CREATE TABLE t5 (
|
||||
a int,
|
||||
b text collate "C",
|
||||
c text collate "C" GENERATED ALWAYS AS (b COLLATE case_insensitive)
|
||||
);
|
||||
INSERT INTO t5 (a, b) values (1, 'D1'), (2, 'D2'), (3, 'd1');
|
||||
-- Collation of c should be the one defined for the column ("C"), not
|
||||
-- the one of the generation expression. (Note that we cannot just
|
||||
-- test with, say, using COLLATION FOR, because the collation of
|
||||
-- function calls is already determined in the parser before
|
||||
-- rewriting.)
|
||||
SELECT * FROM t5 ORDER BY c ASC, a ASC;
|
||||
|
||||
|
||||
-- cleanup
|
||||
RESET search_path;
|
||||
SET client_min_messages TO warning;
|
||||
|
@ -51,7 +51,7 @@ INSERT INTO test_like_id_3 (b) VALUES ('b3');
|
||||
SELECT * FROM test_like_id_3; -- identity was copied and applied
|
||||
DROP TABLE test_like_id_1, test_like_id_2, test_like_id_3;
|
||||
|
||||
CREATE TABLE test_like_gen_1 (a int, b int GENERATED ALWAYS AS (a * 2) STORED);
|
||||
CREATE TABLE test_like_gen_1 (a int, b int GENERATED ALWAYS AS (a * 2) STORED, c int GENERATED ALWAYS AS (a * 3) VIRTUAL);
|
||||
\d test_like_gen_1
|
||||
INSERT INTO test_like_gen_1 (a) VALUES (1);
|
||||
SELECT * FROM test_like_gen_1;
|
||||
|
@ -66,6 +66,17 @@ ALTER TABLE has_volatile ADD col2 int DEFAULT 1;
|
||||
ALTER TABLE has_volatile ADD col3 timestamptz DEFAULT current_timestamp;
|
||||
ALTER TABLE has_volatile ADD col4 int DEFAULT (random() * 10000)::int;
|
||||
|
||||
-- virtual generated columns don't need a rewrite
|
||||
ALTER TABLE has_volatile ADD col5 int GENERATED ALWAYS AS (tableoid::int + col2) VIRTUAL;
|
||||
ALTER TABLE has_volatile ALTER COLUMN col5 TYPE float8;
|
||||
ALTER TABLE has_volatile ALTER COLUMN col5 TYPE numeric;
|
||||
ALTER TABLE has_volatile ALTER COLUMN col5 TYPE numeric;
|
||||
-- here, we do need a rewrite
|
||||
ALTER TABLE has_volatile ALTER COLUMN col1 SET DATA TYPE float8,
|
||||
ADD COLUMN col6 float8 GENERATED ALWAYS AS (col1 * 4) VIRTUAL;
|
||||
-- stored generated columns need a rewrite
|
||||
ALTER TABLE has_volatile ADD col7 int GENERATED ALWAYS AS (55) stored;
|
||||
|
||||
|
||||
|
||||
-- Test a large sample of different datatypes
|
||||
|
@ -1,3 +1,6 @@
|
||||
-- keep these tests aligned with generated_virtual.sql
|
||||
|
||||
|
||||
CREATE SCHEMA generated_stored_tests;
|
||||
GRANT USAGE ON SCHEMA generated_stored_tests TO PUBLIC;
|
||||
SET search_path = generated_stored_tests;
|
||||
@ -149,6 +152,7 @@ DROP TABLE gtest_normal, gtest_normal_child;
|
||||
-- test inheritance mismatches between parent and child
|
||||
CREATE TABLE gtestx (x int, b int DEFAULT 10) INHERITS (gtest1); -- error
|
||||
CREATE TABLE gtestx (x int, b int GENERATED ALWAYS AS IDENTITY) INHERITS (gtest1); -- error
|
||||
CREATE TABLE gtestx (x int, b int GENERATED ALWAYS AS (a * 22) VIRTUAL) INHERITS (gtest1); -- error
|
||||
CREATE TABLE gtestx (x int, b int GENERATED ALWAYS AS (a * 22) STORED) INHERITS (gtest1); -- ok, overrides parent
|
||||
\d+ gtestx
|
||||
INSERT INTO gtestx (a, x) VALUES (11, 22);
|
||||
@ -438,6 +442,9 @@ CREATE TABLE gtest_child3 PARTITION OF gtest_parent (
|
||||
CREATE TABLE gtest_child3 PARTITION OF gtest_parent (
|
||||
f3 WITH OPTIONS GENERATED ALWAYS AS IDENTITY -- error
|
||||
) FOR VALUES FROM ('2016-09-01') TO ('2016-10-01');
|
||||
CREATE TABLE gtest_child3 PARTITION OF gtest_parent (
|
||||
f3 GENERATED ALWAYS AS (f2 * 2) VIRTUAL -- error
|
||||
) FOR VALUES FROM ('2016-09-01') TO ('2016-10-01');
|
||||
CREATE TABLE gtest_child3 (f1 date NOT NULL, f2 bigint, f3 bigint);
|
||||
ALTER TABLE gtest_parent ATTACH PARTITION gtest_child3 FOR VALUES FROM ('2016-09-01') TO ('2016-10-01'); -- error
|
||||
DROP TABLE gtest_child3;
|
||||
@ -447,6 +454,9 @@ DROP TABLE gtest_child3;
|
||||
CREATE TABLE gtest_child3 (f1 date NOT NULL, f2 bigint, f3 bigint GENERATED ALWAYS AS IDENTITY);
|
||||
ALTER TABLE gtest_parent ATTACH PARTITION gtest_child3 FOR VALUES FROM ('2016-09-01') TO ('2016-10-01'); -- error
|
||||
DROP TABLE gtest_child3;
|
||||
CREATE TABLE gtest_child3 (f1 date NOT NULL, f2 bigint, f3 bigint GENERATED ALWAYS AS (f2 * 33) VIRTUAL);
|
||||
ALTER TABLE gtest_parent ATTACH PARTITION gtest_child3 FOR VALUES FROM ('2016-09-01') TO ('2016-10-01'); -- error
|
||||
DROP TABLE gtest_child3;
|
||||
CREATE TABLE gtest_child3 (f1 date NOT NULL, f2 bigint, f3 bigint GENERATED ALWAYS AS (f2 * 33) STORED);
|
||||
ALTER TABLE gtest_parent ATTACH PARTITION gtest_child3 FOR VALUES FROM ('2016-09-01') TO ('2016-10-01');
|
||||
\d gtest_child
|
||||
@ -715,4 +725,4 @@ CREATE TABLE gtest28b (LIKE gtest28a INCLUDING GENERATED);
|
||||
|
||||
|
||||
-- sanity check of system catalog
|
||||
SELECT attrelid, attname, attgenerated FROM pg_attribute WHERE attgenerated NOT IN ('', 's');
|
||||
SELECT attrelid, attname, attgenerated FROM pg_attribute WHERE attgenerated NOT IN ('', 's', 'v');
|
||||
|
734
src/test/regress/sql/generated_virtual.sql
Normal file
734
src/test/regress/sql/generated_virtual.sql
Normal file
@ -0,0 +1,734 @@
|
||||
-- keep these tests aligned with generated_stored.sql
|
||||
|
||||
|
||||
CREATE SCHEMA generated_virtual_tests;
|
||||
GRANT USAGE ON SCHEMA generated_virtual_tests TO PUBLIC;
|
||||
SET search_path = generated_virtual_tests;
|
||||
|
||||
CREATE TABLE gtest0 (a int PRIMARY KEY, b int GENERATED ALWAYS AS (55) VIRTUAL);
|
||||
CREATE TABLE gtest1 (a int PRIMARY KEY, b int GENERATED ALWAYS AS (a * 2) VIRTUAL);
|
||||
|
||||
SELECT table_name, column_name, column_default, is_nullable, is_generated, generation_expression FROM information_schema.columns WHERE table_schema = 'generated_virtual_tests' ORDER BY 1, 2;
|
||||
|
||||
SELECT table_name, column_name, dependent_column FROM information_schema.column_column_usage WHERE table_schema = 'generated_virtual_tests' ORDER BY 1, 2, 3;
|
||||
|
||||
\d gtest1
|
||||
|
||||
-- duplicate generated
|
||||
CREATE TABLE gtest_err_1 (a int PRIMARY KEY, b int GENERATED ALWAYS AS (a * 2) VIRTUAL GENERATED ALWAYS AS (a * 3) VIRTUAL);
|
||||
|
||||
-- references to other generated columns, including self-references
|
||||
CREATE TABLE gtest_err_2a (a int PRIMARY KEY, b int GENERATED ALWAYS AS (b * 2) VIRTUAL);
|
||||
CREATE TABLE gtest_err_2b (a int PRIMARY KEY, b int GENERATED ALWAYS AS (a * 2) VIRTUAL, c int GENERATED ALWAYS AS (b * 3) VIRTUAL);
|
||||
-- a whole-row var is a self-reference on steroids, so disallow that too
|
||||
CREATE TABLE gtest_err_2c (a int PRIMARY KEY,
|
||||
b int GENERATED ALWAYS AS (num_nulls(gtest_err_2c)) VIRTUAL);
|
||||
|
||||
-- invalid reference
|
||||
CREATE TABLE gtest_err_3 (a int PRIMARY KEY, b int GENERATED ALWAYS AS (c * 2) VIRTUAL);
|
||||
|
||||
-- generation expression must be immutable
|
||||
CREATE TABLE gtest_err_4 (a int PRIMARY KEY, b double precision GENERATED ALWAYS AS (random()) VIRTUAL);
|
||||
-- ... but be sure that the immutability test is accurate
|
||||
CREATE TABLE gtest2 (a int, b text GENERATED ALWAYS AS (a || ' sec') VIRTUAL);
|
||||
DROP TABLE gtest2;
|
||||
|
||||
-- cannot have default/identity and generated
|
||||
CREATE TABLE gtest_err_5a (a int PRIMARY KEY, b int DEFAULT 5 GENERATED ALWAYS AS (a * 2) VIRTUAL);
|
||||
CREATE TABLE gtest_err_5b (a int PRIMARY KEY, b int GENERATED ALWAYS AS identity GENERATED ALWAYS AS (a * 2) VIRTUAL);
|
||||
|
||||
-- reference to system column not allowed in generated column
|
||||
-- (except tableoid, which we test below)
|
||||
CREATE TABLE gtest_err_6a (a int PRIMARY KEY, b bool GENERATED ALWAYS AS (xmin <> 37) VIRTUAL);
|
||||
|
||||
-- various prohibited constructs
|
||||
CREATE TABLE gtest_err_7a (a int PRIMARY KEY, b int GENERATED ALWAYS AS (avg(a)) VIRTUAL);
|
||||
CREATE TABLE gtest_err_7b (a int PRIMARY KEY, b int GENERATED ALWAYS AS (row_number() OVER (ORDER BY a)) VIRTUAL);
|
||||
CREATE TABLE gtest_err_7c (a int PRIMARY KEY, b int GENERATED ALWAYS AS ((SELECT a)) VIRTUAL);
|
||||
CREATE TABLE gtest_err_7d (a int PRIMARY KEY, b int GENERATED ALWAYS AS (generate_series(1, a)) VIRTUAL);
|
||||
|
||||
-- GENERATED BY DEFAULT not allowed
|
||||
CREATE TABLE gtest_err_8 (a int PRIMARY KEY, b int GENERATED BY DEFAULT AS (a * 2) VIRTUAL);
|
||||
|
||||
INSERT INTO gtest1 VALUES (1);
|
||||
INSERT INTO gtest1 VALUES (2, DEFAULT); -- ok
|
||||
INSERT INTO gtest1 VALUES (3, 33); -- error
|
||||
INSERT INTO gtest1 VALUES (3, 33), (4, 44); -- error
|
||||
INSERT INTO gtest1 VALUES (3, DEFAULT), (4, 44); -- error
|
||||
INSERT INTO gtest1 VALUES (3, 33), (4, DEFAULT); -- error
|
||||
INSERT INTO gtest1 VALUES (3, DEFAULT), (4, DEFAULT); -- ok
|
||||
|
||||
SELECT * FROM gtest1 ORDER BY a;
|
||||
SELECT gtest1 FROM gtest1 ORDER BY a; -- whole-row reference
|
||||
SELECT a, (SELECT gtest1.b) FROM gtest1 ORDER BY a; -- sublink
|
||||
DELETE FROM gtest1 WHERE a >= 3;
|
||||
|
||||
UPDATE gtest1 SET b = DEFAULT WHERE a = 1;
|
||||
UPDATE gtest1 SET b = 11 WHERE a = 1; -- error
|
||||
|
||||
SELECT * FROM gtest1 ORDER BY a;
|
||||
|
||||
SELECT a, b, b * 2 AS b2 FROM gtest1 ORDER BY a;
|
||||
SELECT a, b FROM gtest1 WHERE b = 4 ORDER BY a;
|
||||
|
||||
-- test that overflow error happens on read
|
||||
INSERT INTO gtest1 VALUES (2000000000);
|
||||
SELECT * FROM gtest1;
|
||||
DELETE FROM gtest1 WHERE a = 2000000000;
|
||||
|
||||
-- test with joins
|
||||
CREATE TABLE gtestx (x int, y int);
|
||||
INSERT INTO gtestx VALUES (11, 1), (22, 2), (33, 3);
|
||||
SELECT * FROM gtestx, gtest1 WHERE gtestx.y = gtest1.a;
|
||||
DROP TABLE gtestx;
|
||||
|
||||
-- test UPDATE/DELETE quals
|
||||
SELECT * FROM gtest1 ORDER BY a;
|
||||
UPDATE gtest1 SET a = 3 WHERE b = 4 RETURNING old.*, new.*;
|
||||
SELECT * FROM gtest1 ORDER BY a;
|
||||
DELETE FROM gtest1 WHERE b = 2;
|
||||
SELECT * FROM gtest1 ORDER BY a;
|
||||
|
||||
-- test MERGE
|
||||
CREATE TABLE gtestm (
|
||||
id int PRIMARY KEY,
|
||||
f1 int,
|
||||
f2 int,
|
||||
f3 int GENERATED ALWAYS AS (f1 * 2) VIRTUAL,
|
||||
f4 int GENERATED ALWAYS AS (f2 * 2) VIRTUAL
|
||||
);
|
||||
INSERT INTO gtestm VALUES (1, 5, 100);
|
||||
MERGE INTO gtestm t USING (VALUES (1, 10), (2, 20)) v(id, f1) ON t.id = v.id
|
||||
WHEN MATCHED THEN UPDATE SET f1 = v.f1
|
||||
WHEN NOT MATCHED THEN INSERT VALUES (v.id, v.f1, 200)
|
||||
RETURNING merge_action(), old.*, new.*;
|
||||
SELECT * FROM gtestm ORDER BY id;
|
||||
DROP TABLE gtestm;
|
||||
|
||||
CREATE TABLE gtestm (
|
||||
a int PRIMARY KEY,
|
||||
b int GENERATED ALWAYS AS (a * 2) VIRTUAL
|
||||
);
|
||||
INSERT INTO gtestm (a) SELECT g FROM generate_series(1, 10) g;
|
||||
MERGE INTO gtestm t USING gtestm AS s ON 2 * t.a = s.b WHEN MATCHED THEN DELETE RETURNING *;
|
||||
DROP TABLE gtestm;
|
||||
|
||||
-- views
|
||||
CREATE VIEW gtest1v AS SELECT * FROM gtest1;
|
||||
SELECT * FROM gtest1v;
|
||||
INSERT INTO gtest1v VALUES (4, 8); -- error
|
||||
INSERT INTO gtest1v VALUES (5, DEFAULT); -- ok
|
||||
INSERT INTO gtest1v VALUES (6, 66), (7, 77); -- error
|
||||
INSERT INTO gtest1v VALUES (6, DEFAULT), (7, 77); -- error
|
||||
INSERT INTO gtest1v VALUES (6, 66), (7, DEFAULT); -- error
|
||||
INSERT INTO gtest1v VALUES (6, DEFAULT), (7, DEFAULT); -- ok
|
||||
|
||||
ALTER VIEW gtest1v ALTER COLUMN b SET DEFAULT 100;
|
||||
INSERT INTO gtest1v VALUES (8, DEFAULT); -- error
|
||||
INSERT INTO gtest1v VALUES (8, DEFAULT), (9, DEFAULT); -- error
|
||||
|
||||
SELECT * FROM gtest1v;
|
||||
DELETE FROM gtest1v WHERE a >= 5;
|
||||
DROP VIEW gtest1v;
|
||||
|
||||
-- CTEs
|
||||
WITH foo AS (SELECT * FROM gtest1) SELECT * FROM foo;
|
||||
|
||||
-- inheritance
|
||||
CREATE TABLE gtest1_1 () INHERITS (gtest1);
|
||||
SELECT * FROM gtest1_1;
|
||||
\d gtest1_1
|
||||
INSERT INTO gtest1_1 VALUES (4);
|
||||
SELECT * FROM gtest1_1;
|
||||
SELECT * FROM gtest1;
|
||||
|
||||
-- can't have generated column that is a child of normal column
|
||||
CREATE TABLE gtest_normal (a int, b int);
|
||||
CREATE TABLE gtest_normal_child (a int, b int GENERATED ALWAYS AS (a * 2) VIRTUAL) INHERITS (gtest_normal); -- error
|
||||
CREATE TABLE gtest_normal_child (a int, b int GENERATED ALWAYS AS (a * 2) VIRTUAL);
|
||||
ALTER TABLE gtest_normal_child INHERIT gtest_normal; -- error
|
||||
DROP TABLE gtest_normal, gtest_normal_child;
|
||||
|
||||
-- test inheritance mismatches between parent and child
|
||||
CREATE TABLE gtestx (x int, b int DEFAULT 10) INHERITS (gtest1); -- error
|
||||
CREATE TABLE gtestx (x int, b int GENERATED ALWAYS AS IDENTITY) INHERITS (gtest1); -- error
|
||||
CREATE TABLE gtestx (x int, b int GENERATED ALWAYS AS (a * 22) STORED) INHERITS (gtest1); -- error
|
||||
CREATE TABLE gtestx (x int, b int GENERATED ALWAYS AS (a * 22) VIRTUAL) INHERITS (gtest1); -- ok, overrides parent
|
||||
\d+ gtestx
|
||||
INSERT INTO gtestx (a, x) VALUES (11, 22);
|
||||
SELECT * FROM gtest1;
|
||||
SELECT * FROM gtestx;
|
||||
|
||||
CREATE TABLE gtestxx_1 (a int NOT NULL, b int);
|
||||
ALTER TABLE gtestxx_1 INHERIT gtest1; -- error
|
||||
CREATE TABLE gtestxx_3 (a int NOT NULL, b int GENERATED ALWAYS AS (a * 2) VIRTUAL);
|
||||
ALTER TABLE gtestxx_3 INHERIT gtest1; -- ok
|
||||
CREATE TABLE gtestxx_4 (b int GENERATED ALWAYS AS (a * 2) VIRTUAL, a int NOT NULL);
|
||||
ALTER TABLE gtestxx_4 INHERIT gtest1; -- ok
|
||||
|
||||
-- test multiple inheritance mismatches
|
||||
CREATE TABLE gtesty (x int, b int DEFAULT 55);
|
||||
CREATE TABLE gtest1_y () INHERITS (gtest0, gtesty); -- error
|
||||
DROP TABLE gtesty;
|
||||
|
||||
CREATE TABLE gtesty (x int, b int);
|
||||
CREATE TABLE gtest1_y () INHERITS (gtest1, gtesty); -- error
|
||||
DROP TABLE gtesty;
|
||||
|
||||
CREATE TABLE gtesty (x int, b int GENERATED ALWAYS AS (x * 22) VIRTUAL);
|
||||
CREATE TABLE gtest1_y () INHERITS (gtest1, gtesty); -- error
|
||||
CREATE TABLE gtest1_y (b int GENERATED ALWAYS AS (x + 1) VIRTUAL) INHERITS (gtest1, gtesty); -- ok
|
||||
\d gtest1_y
|
||||
|
||||
-- test correct handling of GENERATED column that's only in child
|
||||
CREATE TABLE gtestp (f1 int);
|
||||
CREATE TABLE gtestc (f2 int GENERATED ALWAYS AS (f1+1) VIRTUAL) INHERITS(gtestp);
|
||||
INSERT INTO gtestc values(42);
|
||||
TABLE gtestc;
|
||||
UPDATE gtestp SET f1 = f1 * 10;
|
||||
TABLE gtestc;
|
||||
DROP TABLE gtestp CASCADE;
|
||||
|
||||
-- test update
|
||||
CREATE TABLE gtest3 (a int, b int GENERATED ALWAYS AS (a * 3) VIRTUAL);
|
||||
INSERT INTO gtest3 (a) VALUES (1), (2), (3), (NULL);
|
||||
SELECT * FROM gtest3 ORDER BY a;
|
||||
UPDATE gtest3 SET a = 22 WHERE a = 2;
|
||||
SELECT * FROM gtest3 ORDER BY a;
|
||||
|
||||
CREATE TABLE gtest3a (a text, b text GENERATED ALWAYS AS (a || '+' || a) VIRTUAL);
|
||||
INSERT INTO gtest3a (a) VALUES ('a'), ('b'), ('c'), (NULL);
|
||||
SELECT * FROM gtest3a ORDER BY a;
|
||||
UPDATE gtest3a SET a = 'bb' WHERE a = 'b';
|
||||
SELECT * FROM gtest3a ORDER BY a;
|
||||
|
||||
-- COPY
|
||||
TRUNCATE gtest1;
|
||||
INSERT INTO gtest1 (a) VALUES (1), (2);
|
||||
|
||||
COPY gtest1 TO stdout;
|
||||
|
||||
COPY gtest1 (a, b) TO stdout;
|
||||
|
||||
COPY gtest1 FROM stdin;
|
||||
3
|
||||
4
|
||||
\.
|
||||
|
||||
COPY gtest1 (a, b) FROM stdin;
|
||||
|
||||
SELECT * FROM gtest1 ORDER BY a;
|
||||
|
||||
TRUNCATE gtest3;
|
||||
INSERT INTO gtest3 (a) VALUES (1), (2);
|
||||
|
||||
COPY gtest3 TO stdout;
|
||||
|
||||
COPY gtest3 (a, b) TO stdout;
|
||||
|
||||
COPY gtest3 FROM stdin;
|
||||
3
|
||||
4
|
||||
\.
|
||||
|
||||
COPY gtest3 (a, b) FROM stdin;
|
||||
|
||||
SELECT * FROM gtest3 ORDER BY a;
|
||||
|
||||
-- null values
|
||||
CREATE TABLE gtest2 (a int PRIMARY KEY, b int GENERATED ALWAYS AS (NULL) VIRTUAL);
|
||||
INSERT INTO gtest2 VALUES (1);
|
||||
SELECT * FROM gtest2;
|
||||
|
||||
-- simple column reference for varlena types
|
||||
CREATE TABLE gtest_varlena (a varchar, b varchar GENERATED ALWAYS AS (a) VIRTUAL);
|
||||
INSERT INTO gtest_varlena (a) VALUES('01234567890123456789');
|
||||
INSERT INTO gtest_varlena (a) VALUES(NULL);
|
||||
SELECT * FROM gtest_varlena ORDER BY a;
|
||||
DROP TABLE gtest_varlena;
|
||||
|
||||
-- composite types
|
||||
CREATE TYPE double_int as (a int, b int);
|
||||
CREATE TABLE gtest4 (
|
||||
a int,
|
||||
b double_int GENERATED ALWAYS AS ((a * 2, a * 3)) VIRTUAL
|
||||
);
|
||||
INSERT INTO gtest4 VALUES (1), (6);
|
||||
SELECT * FROM gtest4;
|
||||
|
||||
DROP TABLE gtest4;
|
||||
DROP TYPE double_int;
|
||||
|
||||
-- using tableoid is allowed
|
||||
CREATE TABLE gtest_tableoid (
|
||||
a int PRIMARY KEY,
|
||||
b bool GENERATED ALWAYS AS (tableoid = 'gtest_tableoid'::regclass) VIRTUAL
|
||||
);
|
||||
INSERT INTO gtest_tableoid VALUES (1), (2);
|
||||
ALTER TABLE gtest_tableoid ADD COLUMN
|
||||
c regclass GENERATED ALWAYS AS (tableoid) VIRTUAL;
|
||||
SELECT * FROM gtest_tableoid;
|
||||
|
||||
-- drop column behavior
|
||||
CREATE TABLE gtest10 (a int PRIMARY KEY, b int, c int GENERATED ALWAYS AS (b * 2) VIRTUAL);
|
||||
ALTER TABLE gtest10 DROP COLUMN b; -- fails
|
||||
ALTER TABLE gtest10 DROP COLUMN b CASCADE; -- drops c too
|
||||
|
||||
\d gtest10
|
||||
|
||||
CREATE TABLE gtest10a (a int PRIMARY KEY, b int GENERATED ALWAYS AS (a * 2) VIRTUAL);
|
||||
ALTER TABLE gtest10a DROP COLUMN b;
|
||||
INSERT INTO gtest10a (a) VALUES (1);
|
||||
|
||||
-- privileges
|
||||
CREATE USER regress_user11;
|
||||
|
||||
CREATE TABLE gtest11 (a int PRIMARY KEY, b int, c int GENERATED ALWAYS AS (b * 2) VIRTUAL);
|
||||
INSERT INTO gtest11 VALUES (1, 10), (2, 20);
|
||||
GRANT SELECT (a, c) ON gtest11 TO regress_user11;
|
||||
|
||||
CREATE FUNCTION gf1(a int) RETURNS int AS $$ SELECT a * 3 $$ IMMUTABLE LANGUAGE SQL;
|
||||
REVOKE ALL ON FUNCTION gf1(int) FROM PUBLIC;
|
||||
|
||||
CREATE TABLE gtest12 (a int PRIMARY KEY, b int, c int GENERATED ALWAYS AS (gf1(b)) VIRTUAL);
|
||||
INSERT INTO gtest12 VALUES (1, 10), (2, 20);
|
||||
GRANT SELECT (a, c), INSERT ON gtest12 TO regress_user11;
|
||||
|
||||
SET ROLE regress_user11;
|
||||
SELECT a, b FROM gtest11; -- not allowed
|
||||
SELECT a, c FROM gtest11; -- allowed
|
||||
SELECT gf1(10); -- not allowed
|
||||
INSERT INTO gtest12 VALUES (3, 30), (4, 40); -- allowed (does not actually invoke the function)
|
||||
SELECT a, c FROM gtest12; -- currently not allowed because of function permissions, should arguably be allowed
|
||||
RESET ROLE;
|
||||
|
||||
DROP FUNCTION gf1(int); -- fail
|
||||
DROP TABLE gtest11, gtest12;
|
||||
DROP FUNCTION gf1(int);
|
||||
DROP USER regress_user11;
|
||||
|
||||
-- check constraints
|
||||
CREATE TABLE gtest20 (a int PRIMARY KEY, b int GENERATED ALWAYS AS (a * 2) VIRTUAL CHECK (b < 50));
|
||||
INSERT INTO gtest20 (a) VALUES (10); -- ok
|
||||
INSERT INTO gtest20 (a) VALUES (30); -- violates constraint
|
||||
|
||||
ALTER TABLE gtest20 ALTER COLUMN b SET EXPRESSION AS (a * 100); -- violates constraint (currently not supported)
|
||||
ALTER TABLE gtest20 ALTER COLUMN b SET EXPRESSION AS (a * 3); -- ok (currently not supported)
|
||||
|
||||
CREATE TABLE gtest20a (a int PRIMARY KEY, b int GENERATED ALWAYS AS (a * 2) VIRTUAL);
|
||||
INSERT INTO gtest20a (a) VALUES (10);
|
||||
INSERT INTO gtest20a (a) VALUES (30);
|
||||
ALTER TABLE gtest20a ADD CHECK (b < 50); -- fails on existing row
|
||||
|
||||
CREATE TABLE gtest20b (a int PRIMARY KEY, b int GENERATED ALWAYS AS (a * 2) VIRTUAL);
|
||||
INSERT INTO gtest20b (a) VALUES (10);
|
||||
INSERT INTO gtest20b (a) VALUES (30);
|
||||
ALTER TABLE gtest20b ADD CONSTRAINT chk CHECK (b < 50) NOT VALID;
|
||||
ALTER TABLE gtest20b VALIDATE CONSTRAINT chk; -- fails on existing row
|
||||
|
||||
-- check with whole-row reference
|
||||
CREATE TABLE gtest20c (a int, b int GENERATED ALWAYS AS (a * 2) VIRTUAL);
|
||||
ALTER TABLE gtest20c ADD CONSTRAINT whole_row_check CHECK (gtest20c IS NOT NULL);
|
||||
INSERT INTO gtest20c VALUES (1); -- ok
|
||||
INSERT INTO gtest20c VALUES (NULL); -- fails
|
||||
|
||||
-- not-null constraints (currently not supported)
|
||||
CREATE TABLE gtest21a (a int PRIMARY KEY, b int GENERATED ALWAYS AS (nullif(a, 0)) VIRTUAL NOT NULL);
|
||||
--INSERT INTO gtest21a (a) VALUES (1); -- ok
|
||||
--INSERT INTO gtest21a (a) VALUES (0); -- violates constraint
|
||||
|
||||
-- also check with table constraint syntax
|
||||
CREATE TABLE gtest21ax (a int PRIMARY KEY, b int GENERATED ALWAYS AS (nullif(a, 0)) VIRTUAL, CONSTRAINT cc NOT NULL b); -- error
|
||||
CREATE TABLE gtest21ax (a int PRIMARY KEY, b int GENERATED ALWAYS AS (nullif(a, 0)) VIRTUAL);
|
||||
ALTER TABLE gtest21ax ADD CONSTRAINT cc NOT NULL b; -- error
|
||||
DROP TABLE gtest21ax;
|
||||
|
||||
CREATE TABLE gtest21b (a int PRIMARY KEY, b int GENERATED ALWAYS AS (nullif(a, 0)) VIRTUAL);
|
||||
ALTER TABLE gtest21b ALTER COLUMN b SET NOT NULL;
|
||||
--INSERT INTO gtest21b (a) VALUES (1); -- ok
|
||||
--INSERT INTO gtest21b (a) VALUES (0); -- violates constraint
|
||||
ALTER TABLE gtest21b ALTER COLUMN b DROP NOT NULL;
|
||||
--INSERT INTO gtest21b (a) VALUES (0); -- ok now
|
||||
|
||||
-- index constraints
|
||||
CREATE TABLE gtest22a (a int PRIMARY KEY, b int GENERATED ALWAYS AS (a / 2) VIRTUAL UNIQUE);
|
||||
--INSERT INTO gtest22a VALUES (2);
|
||||
--INSERT INTO gtest22a VALUES (3);
|
||||
--INSERT INTO gtest22a VALUES (4);
|
||||
CREATE TABLE gtest22b (a int, b int GENERATED ALWAYS AS (a / 2) VIRTUAL, PRIMARY KEY (a, b));
|
||||
--INSERT INTO gtest22b VALUES (2);
|
||||
--INSERT INTO gtest22b VALUES (2);
|
||||
|
||||
-- indexes
|
||||
CREATE TABLE gtest22c (a int, b int GENERATED ALWAYS AS (a * 2) VIRTUAL);
|
||||
--CREATE INDEX gtest22c_b_idx ON gtest22c (b);
|
||||
--CREATE INDEX gtest22c_expr_idx ON gtest22c ((b * 3));
|
||||
--CREATE INDEX gtest22c_pred_idx ON gtest22c (a) WHERE b > 0;
|
||||
--\d gtest22c
|
||||
|
||||
--INSERT INTO gtest22c VALUES (1), (2), (3);
|
||||
--SET enable_seqscan TO off;
|
||||
--SET enable_bitmapscan TO off;
|
||||
--EXPLAIN (COSTS OFF) SELECT * FROM gtest22c WHERE b = 4;
|
||||
--SELECT * FROM gtest22c WHERE b = 4;
|
||||
--EXPLAIN (COSTS OFF) SELECT * FROM gtest22c WHERE b * 3 = 6;
|
||||
--SELECT * FROM gtest22c WHERE b * 3 = 6;
|
||||
--EXPLAIN (COSTS OFF) SELECT * FROM gtest22c WHERE a = 1 AND b > 0;
|
||||
--SELECT * FROM gtest22c WHERE a = 1 AND b > 0;
|
||||
|
||||
--ALTER TABLE gtest22c ALTER COLUMN b SET EXPRESSION AS (a * 4);
|
||||
--ANALYZE gtest22c;
|
||||
--EXPLAIN (COSTS OFF) SELECT * FROM gtest22c WHERE b = 8;
|
||||
--SELECT * FROM gtest22c WHERE b = 8;
|
||||
--EXPLAIN (COSTS OFF) SELECT * FROM gtest22c WHERE b * 3 = 12;
|
||||
--SELECT * FROM gtest22c WHERE b * 3 = 12;
|
||||
--EXPLAIN (COSTS OFF) SELECT * FROM gtest22c WHERE a = 1 AND b > 0;
|
||||
--SELECT * FROM gtest22c WHERE a = 1 AND b > 0;
|
||||
--RESET enable_seqscan;
|
||||
--RESET enable_bitmapscan;
|
||||
|
||||
-- foreign keys
|
||||
CREATE TABLE gtest23a (x int PRIMARY KEY, y int);
|
||||
--INSERT INTO gtest23a VALUES (1, 11), (2, 22), (3, 33);
|
||||
|
||||
CREATE TABLE gtest23x (a int PRIMARY KEY, b int GENERATED ALWAYS AS (a * 2) VIRTUAL REFERENCES gtest23a (x) ON UPDATE CASCADE); -- error
|
||||
CREATE TABLE gtest23x (a int PRIMARY KEY, b int GENERATED ALWAYS AS (a * 2) VIRTUAL REFERENCES gtest23a (x) ON DELETE SET NULL); -- error
|
||||
|
||||
CREATE TABLE gtest23b (a int PRIMARY KEY, b int GENERATED ALWAYS AS (a * 2) VIRTUAL REFERENCES gtest23a (x));
|
||||
--\d gtest23b
|
||||
|
||||
--INSERT INTO gtest23b VALUES (1); -- ok
|
||||
--INSERT INTO gtest23b VALUES (5); -- error
|
||||
--ALTER TABLE gtest23b ALTER COLUMN b SET EXPRESSION AS (a * 5); -- error
|
||||
--ALTER TABLE gtest23b ALTER COLUMN b SET EXPRESSION AS (a * 1); -- ok
|
||||
|
||||
--DROP TABLE gtest23b;
|
||||
--DROP TABLE gtest23a;
|
||||
|
||||
CREATE TABLE gtest23p (x int, y int GENERATED ALWAYS AS (x * 2) VIRTUAL, PRIMARY KEY (y));
|
||||
--INSERT INTO gtest23p VALUES (1), (2), (3);
|
||||
|
||||
CREATE TABLE gtest23q (a int PRIMARY KEY, b int REFERENCES gtest23p (y));
|
||||
--INSERT INTO gtest23q VALUES (1, 2); -- ok
|
||||
--INSERT INTO gtest23q VALUES (2, 5); -- error
|
||||
|
||||
-- domains
|
||||
CREATE DOMAIN gtestdomain1 AS int CHECK (VALUE < 10);
|
||||
CREATE TABLE gtest24 (a int PRIMARY KEY, b gtestdomain1 GENERATED ALWAYS AS (a * 2) VIRTUAL);
|
||||
--INSERT INTO gtest24 (a) VALUES (4); -- ok
|
||||
--INSERT INTO gtest24 (a) VALUES (6); -- error
|
||||
CREATE TYPE gtestdomain1range AS range (subtype = gtestdomain1);
|
||||
CREATE TABLE gtest24r (a int PRIMARY KEY, b gtestdomain1range GENERATED ALWAYS AS (gtestdomain1range(a, a + 5)) VIRTUAL);
|
||||
--INSERT INTO gtest24r (a) VALUES (4); -- ok
|
||||
--INSERT INTO gtest24r (a) VALUES (6); -- error
|
||||
|
||||
-- typed tables (currently not supported)
|
||||
CREATE TYPE gtest_type AS (f1 integer, f2 text, f3 bigint);
|
||||
CREATE TABLE gtest28 OF gtest_type (f1 WITH OPTIONS GENERATED ALWAYS AS (f2 *2) VIRTUAL);
|
||||
DROP TYPE gtest_type CASCADE;
|
||||
|
||||
-- partitioning cases
|
||||
CREATE TABLE gtest_parent (f1 date NOT NULL, f2 bigint, f3 bigint) PARTITION BY RANGE (f1);
|
||||
CREATE TABLE gtest_child PARTITION OF gtest_parent (
|
||||
f3 WITH OPTIONS GENERATED ALWAYS AS (f2 * 2) VIRTUAL
|
||||
) FOR VALUES FROM ('2016-07-01') TO ('2016-08-01'); -- error
|
||||
CREATE TABLE gtest_child (f1 date NOT NULL, f2 bigint, f3 bigint GENERATED ALWAYS AS (f2 * 2) VIRTUAL);
|
||||
ALTER TABLE gtest_parent ATTACH PARTITION gtest_child FOR VALUES FROM ('2016-07-01') TO ('2016-08-01'); -- error
|
||||
DROP TABLE gtest_parent, gtest_child;
|
||||
|
||||
CREATE TABLE gtest_parent (f1 date NOT NULL, f2 bigint, f3 bigint GENERATED ALWAYS AS (f2 * 2) VIRTUAL) PARTITION BY RANGE (f1);
|
||||
CREATE TABLE gtest_child PARTITION OF gtest_parent
|
||||
FOR VALUES FROM ('2016-07-01') TO ('2016-08-01'); -- inherits gen expr
|
||||
CREATE TABLE gtest_child2 PARTITION OF gtest_parent (
|
||||
f3 WITH OPTIONS GENERATED ALWAYS AS (f2 * 22) VIRTUAL -- overrides gen expr
|
||||
) FOR VALUES FROM ('2016-08-01') TO ('2016-09-01');
|
||||
CREATE TABLE gtest_child3 PARTITION OF gtest_parent (
|
||||
f3 DEFAULT 42 -- error
|
||||
) FOR VALUES FROM ('2016-09-01') TO ('2016-10-01');
|
||||
CREATE TABLE gtest_child3 PARTITION OF gtest_parent (
|
||||
f3 WITH OPTIONS GENERATED ALWAYS AS IDENTITY -- error
|
||||
) FOR VALUES FROM ('2016-09-01') TO ('2016-10-01');
|
||||
CREATE TABLE gtest_child3 PARTITION OF gtest_parent (
|
||||
f3 GENERATED ALWAYS AS (f2 * 2) STORED -- error
|
||||
) FOR VALUES FROM ('2016-09-01') TO ('2016-10-01');
|
||||
CREATE TABLE gtest_child3 (f1 date NOT NULL, f2 bigint, f3 bigint);
|
||||
ALTER TABLE gtest_parent ATTACH PARTITION gtest_child3 FOR VALUES FROM ('2016-09-01') TO ('2016-10-01'); -- error
|
||||
DROP TABLE gtest_child3;
|
||||
CREATE TABLE gtest_child3 (f1 date NOT NULL, f2 bigint, f3 bigint DEFAULT 42);
|
||||
ALTER TABLE gtest_parent ATTACH PARTITION gtest_child3 FOR VALUES FROM ('2016-09-01') TO ('2016-10-01'); -- error
|
||||
DROP TABLE gtest_child3;
|
||||
CREATE TABLE gtest_child3 (f1 date NOT NULL, f2 bigint, f3 bigint GENERATED ALWAYS AS IDENTITY);
|
||||
ALTER TABLE gtest_parent ATTACH PARTITION gtest_child3 FOR VALUES FROM ('2016-09-01') TO ('2016-10-01'); -- error
|
||||
DROP TABLE gtest_child3;
|
||||
CREATE TABLE gtest_child3 (f1 date NOT NULL, f2 bigint, f3 bigint GENERATED ALWAYS AS (f2 * 33) STORED);
|
||||
ALTER TABLE gtest_parent ATTACH PARTITION gtest_child3 FOR VALUES FROM ('2016-09-01') TO ('2016-10-01'); -- error
|
||||
DROP TABLE gtest_child3;
|
||||
CREATE TABLE gtest_child3 (f1 date NOT NULL, f2 bigint, f3 bigint GENERATED ALWAYS AS (f2 * 33) VIRTUAL);
|
||||
ALTER TABLE gtest_parent ATTACH PARTITION gtest_child3 FOR VALUES FROM ('2016-09-01') TO ('2016-10-01');
|
||||
\d gtest_child
|
||||
\d gtest_child2
|
||||
\d gtest_child3
|
||||
INSERT INTO gtest_parent (f1, f2) VALUES ('2016-07-15', 1);
|
||||
INSERT INTO gtest_parent (f1, f2) VALUES ('2016-07-15', 2);
|
||||
INSERT INTO gtest_parent (f1, f2) VALUES ('2016-08-15', 3);
|
||||
SELECT tableoid::regclass, * FROM gtest_parent ORDER BY 1, 2, 3;
|
||||
SELECT tableoid::regclass, * FROM gtest_child ORDER BY 1, 2, 3;
|
||||
SELECT tableoid::regclass, * FROM gtest_child2 ORDER BY 1, 2, 3; -- uses child's generation expression, not parent's
|
||||
SELECT tableoid::regclass, * FROM gtest_child3 ORDER BY 1, 2, 3;
|
||||
UPDATE gtest_parent SET f1 = f1 + 60 WHERE f2 = 1;
|
||||
SELECT tableoid::regclass, * FROM gtest_parent ORDER BY 1, 2, 3;
|
||||
|
||||
-- alter only parent's and one child's generation expression
|
||||
ALTER TABLE ONLY gtest_parent ALTER COLUMN f3 SET EXPRESSION AS (f2 * 4);
|
||||
ALTER TABLE gtest_child ALTER COLUMN f3 SET EXPRESSION AS (f2 * 10);
|
||||
\d gtest_parent
|
||||
\d gtest_child
|
||||
\d gtest_child2
|
||||
\d gtest_child3
|
||||
SELECT tableoid::regclass, * FROM gtest_parent ORDER BY 1, 2, 3;
|
||||
|
||||
-- alter generation expression of parent and all its children altogether
|
||||
ALTER TABLE gtest_parent ALTER COLUMN f3 SET EXPRESSION AS (f2 * 2);
|
||||
\d gtest_parent
|
||||
\d gtest_child
|
||||
\d gtest_child2
|
||||
\d gtest_child3
|
||||
SELECT tableoid::regclass, * FROM gtest_parent ORDER BY 1, 2, 3;
|
||||
-- we leave these tables around for purposes of testing dump/reload/upgrade
|
||||
|
||||
-- generated columns in partition key (not allowed)
|
||||
CREATE TABLE gtest_part_key (f1 date NOT NULL, f2 bigint, f3 bigint GENERATED ALWAYS AS (f2 * 2) VIRTUAL) PARTITION BY RANGE (f3);
|
||||
CREATE TABLE gtest_part_key (f1 date NOT NULL, f2 bigint, f3 bigint GENERATED ALWAYS AS (f2 * 2) VIRTUAL) PARTITION BY RANGE ((f3 * 3));
|
||||
|
||||
-- ALTER TABLE ... ADD COLUMN
|
||||
CREATE TABLE gtest25 (a int PRIMARY KEY);
|
||||
INSERT INTO gtest25 VALUES (3), (4);
|
||||
ALTER TABLE gtest25 ADD COLUMN b int GENERATED ALWAYS AS (a * 2) VIRTUAL, ALTER COLUMN b SET EXPRESSION AS (a * 3);
|
||||
SELECT * FROM gtest25 ORDER BY a;
|
||||
ALTER TABLE gtest25 ADD COLUMN x int GENERATED ALWAYS AS (b * 4) VIRTUAL; -- error
|
||||
ALTER TABLE gtest25 ADD COLUMN x int GENERATED ALWAYS AS (z * 4) VIRTUAL; -- error
|
||||
ALTER TABLE gtest25 ADD COLUMN c int DEFAULT 42,
|
||||
ADD COLUMN x int GENERATED ALWAYS AS (c * 4) VIRTUAL;
|
||||
ALTER TABLE gtest25 ADD COLUMN d int DEFAULT 101;
|
||||
ALTER TABLE gtest25 ALTER COLUMN d SET DATA TYPE float8,
|
||||
ADD COLUMN y float8 GENERATED ALWAYS AS (d * 4) VIRTUAL;
|
||||
SELECT * FROM gtest25 ORDER BY a;
|
||||
\d gtest25
|
||||
|
||||
-- ALTER TABLE ... ALTER COLUMN
|
||||
CREATE TABLE gtest27 (
|
||||
a int,
|
||||
b int,
|
||||
x int GENERATED ALWAYS AS ((a + b) * 2) VIRTUAL
|
||||
);
|
||||
INSERT INTO gtest27 (a, b) VALUES (3, 7), (4, 11);
|
||||
ALTER TABLE gtest27 ALTER COLUMN a TYPE text; -- error
|
||||
ALTER TABLE gtest27 ALTER COLUMN x TYPE numeric;
|
||||
\d gtest27
|
||||
SELECT * FROM gtest27;
|
||||
ALTER TABLE gtest27 ALTER COLUMN x TYPE boolean USING x <> 0; -- error
|
||||
ALTER TABLE gtest27 ALTER COLUMN x DROP DEFAULT; -- error
|
||||
-- It's possible to alter the column types this way:
|
||||
ALTER TABLE gtest27
|
||||
DROP COLUMN x,
|
||||
ALTER COLUMN a TYPE bigint,
|
||||
ALTER COLUMN b TYPE bigint,
|
||||
ADD COLUMN x bigint GENERATED ALWAYS AS ((a + b) * 2) VIRTUAL;
|
||||
\d gtest27
|
||||
-- Ideally you could just do this, but not today (and should x change type?):
|
||||
ALTER TABLE gtest27
|
||||
ALTER COLUMN a TYPE float8,
|
||||
ALTER COLUMN b TYPE float8; -- error
|
||||
\d gtest27
|
||||
SELECT * FROM gtest27;
|
||||
|
||||
-- ALTER TABLE ... ALTER COLUMN ... DROP EXPRESSION
|
||||
CREATE TABLE gtest29 (
|
||||
a int,
|
||||
b int GENERATED ALWAYS AS (a * 2) VIRTUAL
|
||||
);
|
||||
INSERT INTO gtest29 (a) VALUES (3), (4);
|
||||
SELECT * FROM gtest29;
|
||||
\d gtest29
|
||||
ALTER TABLE gtest29 ALTER COLUMN a SET EXPRESSION AS (a * 3); -- error
|
||||
ALTER TABLE gtest29 ALTER COLUMN a DROP EXPRESSION; -- error
|
||||
ALTER TABLE gtest29 ALTER COLUMN a DROP EXPRESSION IF EXISTS; -- notice
|
||||
|
||||
-- Change the expression
|
||||
ALTER TABLE gtest29 ALTER COLUMN b SET EXPRESSION AS (a * 3);
|
||||
SELECT * FROM gtest29;
|
||||
\d gtest29
|
||||
|
||||
ALTER TABLE gtest29 ALTER COLUMN b DROP EXPRESSION; -- not supported
|
||||
INSERT INTO gtest29 (a) VALUES (5);
|
||||
INSERT INTO gtest29 (a, b) VALUES (6, 66);
|
||||
SELECT * FROM gtest29;
|
||||
\d gtest29
|
||||
|
||||
-- check that dependencies between columns have also been removed
|
||||
--ALTER TABLE gtest29 DROP COLUMN a; -- should not drop b
|
||||
--\d gtest29
|
||||
|
||||
-- with inheritance
|
||||
CREATE TABLE gtest30 (
|
||||
a int,
|
||||
b int GENERATED ALWAYS AS (a * 2) VIRTUAL
|
||||
);
|
||||
CREATE TABLE gtest30_1 () INHERITS (gtest30);
|
||||
ALTER TABLE gtest30 ALTER COLUMN b DROP EXPRESSION;
|
||||
\d gtest30
|
||||
\d gtest30_1
|
||||
DROP TABLE gtest30 CASCADE;
|
||||
CREATE TABLE gtest30 (
|
||||
a int,
|
||||
b int GENERATED ALWAYS AS (a * 2) VIRTUAL
|
||||
);
|
||||
CREATE TABLE gtest30_1 () INHERITS (gtest30);
|
||||
ALTER TABLE ONLY gtest30 ALTER COLUMN b DROP EXPRESSION; -- error
|
||||
\d gtest30
|
||||
\d gtest30_1
|
||||
ALTER TABLE gtest30_1 ALTER COLUMN b DROP EXPRESSION; -- error
|
||||
|
||||
-- composite type dependencies
|
||||
CREATE TABLE gtest31_1 (a int, b text GENERATED ALWAYS AS ('hello') VIRTUAL, c text);
|
||||
CREATE TABLE gtest31_2 (x int, y gtest31_1);
|
||||
ALTER TABLE gtest31_1 ALTER COLUMN b TYPE varchar; -- fails
|
||||
DROP TABLE gtest31_1, gtest31_2;
|
||||
|
||||
-- Check it for a partitioned table, too
|
||||
CREATE TABLE gtest31_1 (a int, b text GENERATED ALWAYS AS ('hello') VIRTUAL, c text) PARTITION BY LIST (a);
|
||||
CREATE TABLE gtest31_2 (x int, y gtest31_1);
|
||||
ALTER TABLE gtest31_1 ALTER COLUMN b TYPE varchar; -- fails
|
||||
DROP TABLE gtest31_1, gtest31_2;
|
||||
|
||||
-- triggers
|
||||
CREATE TABLE gtest26 (
|
||||
a int PRIMARY KEY,
|
||||
b int GENERATED ALWAYS AS (a * 2) VIRTUAL
|
||||
);
|
||||
|
||||
CREATE FUNCTION gtest_trigger_func() RETURNS trigger
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
IF tg_op IN ('DELETE', 'UPDATE') THEN
|
||||
RAISE INFO '%: %: old = %', TG_NAME, TG_WHEN, OLD;
|
||||
END IF;
|
||||
IF tg_op IN ('INSERT', 'UPDATE') THEN
|
||||
RAISE INFO '%: %: new = %', TG_NAME, TG_WHEN, NEW;
|
||||
END IF;
|
||||
IF tg_op = 'DELETE' THEN
|
||||
RETURN OLD;
|
||||
ELSE
|
||||
RETURN NEW;
|
||||
END IF;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE TRIGGER gtest1 BEFORE DELETE OR UPDATE ON gtest26
|
||||
FOR EACH ROW
|
||||
WHEN (OLD.b < 0) -- ok
|
||||
EXECUTE PROCEDURE gtest_trigger_func();
|
||||
|
||||
CREATE TRIGGER gtest2a BEFORE INSERT OR UPDATE ON gtest26
|
||||
FOR EACH ROW
|
||||
WHEN (NEW.b < 0) -- error
|
||||
EXECUTE PROCEDURE gtest_trigger_func();
|
||||
|
||||
CREATE TRIGGER gtest2b BEFORE INSERT OR UPDATE ON gtest26
|
||||
FOR EACH ROW
|
||||
WHEN (NEW.* IS NOT NULL) -- error
|
||||
EXECUTE PROCEDURE gtest_trigger_func();
|
||||
|
||||
CREATE TRIGGER gtest2 BEFORE INSERT ON gtest26
|
||||
FOR EACH ROW
|
||||
WHEN (NEW.a < 0)
|
||||
EXECUTE PROCEDURE gtest_trigger_func();
|
||||
|
||||
CREATE TRIGGER gtest3 AFTER DELETE OR UPDATE ON gtest26
|
||||
FOR EACH ROW
|
||||
WHEN (OLD.b < 0) -- ok
|
||||
EXECUTE PROCEDURE gtest_trigger_func();
|
||||
|
||||
CREATE TRIGGER gtest4 AFTER INSERT OR UPDATE ON gtest26
|
||||
FOR EACH ROW
|
||||
WHEN (NEW.b < 0) -- ok
|
||||
EXECUTE PROCEDURE gtest_trigger_func();
|
||||
|
||||
INSERT INTO gtest26 (a) VALUES (-2), (0), (3);
|
||||
SELECT * FROM gtest26 ORDER BY a;
|
||||
UPDATE gtest26 SET a = a * -2;
|
||||
SELECT * FROM gtest26 ORDER BY a;
|
||||
DELETE FROM gtest26 WHERE a = -6;
|
||||
SELECT * FROM gtest26 ORDER BY a;
|
||||
|
||||
DROP TRIGGER gtest1 ON gtest26;
|
||||
DROP TRIGGER gtest2 ON gtest26;
|
||||
DROP TRIGGER gtest3 ON gtest26;
|
||||
|
||||
-- Check that an UPDATE of "a" fires the trigger for UPDATE OF b, per
|
||||
-- SQL standard.
|
||||
CREATE FUNCTION gtest_trigger_func3() RETURNS trigger
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
RAISE NOTICE 'OK';
|
||||
RETURN NEW;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE TRIGGER gtest11 BEFORE UPDATE OF b ON gtest26
|
||||
FOR EACH ROW
|
||||
EXECUTE PROCEDURE gtest_trigger_func3();
|
||||
|
||||
UPDATE gtest26 SET a = 1 WHERE a = 0;
|
||||
|
||||
DROP TRIGGER gtest11 ON gtest26;
|
||||
TRUNCATE gtest26;
|
||||
|
||||
-- check that modifications of generated columns in triggers do
|
||||
-- not get propagated
|
||||
CREATE FUNCTION gtest_trigger_func4() RETURNS trigger
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
NEW.a = 10;
|
||||
NEW.b = 300;
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$;
|
||||
|
||||
CREATE TRIGGER gtest12_01 BEFORE INSERT OR UPDATE ON gtest26
|
||||
FOR EACH ROW
|
||||
EXECUTE PROCEDURE gtest_trigger_func();
|
||||
|
||||
CREATE TRIGGER gtest12_02 BEFORE INSERT OR UPDATE ON gtest26
|
||||
FOR EACH ROW
|
||||
EXECUTE PROCEDURE gtest_trigger_func4();
|
||||
|
||||
CREATE TRIGGER gtest12_03 BEFORE INSERT OR UPDATE ON gtest26
|
||||
FOR EACH ROW
|
||||
EXECUTE PROCEDURE gtest_trigger_func();
|
||||
|
||||
INSERT INTO gtest26 (a) VALUES (1);
|
||||
SELECT * FROM gtest26 ORDER BY a;
|
||||
UPDATE gtest26 SET a = 11 WHERE a = 10;
|
||||
SELECT * FROM gtest26 ORDER BY a;
|
||||
|
||||
-- LIKE INCLUDING GENERATED and dropped column handling
|
||||
CREATE TABLE gtest28a (
|
||||
a int,
|
||||
b int,
|
||||
c int,
|
||||
x int GENERATED ALWAYS AS (b * 2) VIRTUAL
|
||||
);
|
||||
|
||||
ALTER TABLE gtest28a DROP COLUMN a;
|
||||
|
||||
CREATE TABLE gtest28b (LIKE gtest28a INCLUDING GENERATED);
|
||||
|
||||
\d gtest28*
|
||||
|
||||
|
||||
-- sanity check of system catalog
|
||||
SELECT attrelid, attname, attgenerated FROM pg_attribute WHERE attgenerated NOT IN ('', 's', 'v');
|
@ -214,7 +214,7 @@ CREATE FUNCTION testpub_rf_func1(integer, integer) RETURNS boolean AS $$ SELECT
|
||||
CREATE OPERATOR =#> (PROCEDURE = testpub_rf_func1, LEFTARG = integer, RIGHTARG = integer);
|
||||
CREATE PUBLICATION testpub6 FOR TABLE testpub_rf_tbl3 WHERE (e =#> 27);
|
||||
-- fail - user-defined functions are not allowed
|
||||
CREATE FUNCTION testpub_rf_func2() RETURNS integer AS $$ BEGIN RETURN 123; END; $$ LANGUAGE plpgsql;
|
||||
CREATE FUNCTION testpub_rf_func2() RETURNS integer IMMUTABLE AS $$ BEGIN RETURN 123; END; $$ LANGUAGE plpgsql;
|
||||
ALTER PUBLICATION testpub5 ADD TABLE testpub_rf_tbl1 WHERE (a >= testpub_rf_func2());
|
||||
-- fail - non-immutable functions are not allowed. random() is volatile.
|
||||
ALTER PUBLICATION testpub5 ADD TABLE testpub_rf_tbl1 WHERE (a < random());
|
||||
@ -261,18 +261,30 @@ CREATE PUBLICATION testpub6 FOR TABLES IN SCHEMA testpub_rf_schema2;
|
||||
ALTER PUBLICATION testpub6 SET TABLES IN SCHEMA testpub_rf_schema2, TABLE testpub_rf_schema2.testpub_rf_tbl6 WHERE (i < 99);
|
||||
RESET client_min_messages;
|
||||
\dRp+ testpub6
|
||||
-- fail - virtual generated column uses user-defined function
|
||||
CREATE TABLE testpub_rf_tbl6 (id int PRIMARY KEY, x int, y int GENERATED ALWAYS AS (x * testpub_rf_func2()) VIRTUAL);
|
||||
CREATE PUBLICATION testpub7 FOR TABLE testpub_rf_tbl6 WHERE (y > 100);
|
||||
-- test that SET EXPRESSION is rejected, because it could affect a row filter
|
||||
SET client_min_messages = 'ERROR';
|
||||
CREATE TABLE testpub_rf_tbl7 (id int PRIMARY KEY, x int, y int GENERATED ALWAYS AS (x * 111) VIRTUAL);
|
||||
CREATE PUBLICATION testpub8 FOR TABLE testpub_rf_tbl7 WHERE (y > 100);
|
||||
ALTER TABLE testpub_rf_tbl7 ALTER COLUMN y SET EXPRESSION AS (x * testpub_rf_func2());
|
||||
RESET client_min_messages;
|
||||
|
||||
DROP TABLE testpub_rf_tbl1;
|
||||
DROP TABLE testpub_rf_tbl2;
|
||||
DROP TABLE testpub_rf_tbl3;
|
||||
DROP TABLE testpub_rf_tbl4;
|
||||
DROP TABLE testpub_rf_tbl5;
|
||||
DROP TABLE testpub_rf_tbl6;
|
||||
DROP TABLE testpub_rf_schema1.testpub_rf_tbl5;
|
||||
DROP TABLE testpub_rf_schema2.testpub_rf_tbl6;
|
||||
DROP SCHEMA testpub_rf_schema1;
|
||||
DROP SCHEMA testpub_rf_schema2;
|
||||
DROP PUBLICATION testpub5;
|
||||
DROP PUBLICATION testpub6;
|
||||
DROP PUBLICATION testpub8;
|
||||
DROP TABLE testpub_rf_tbl7;
|
||||
DROP OPERATOR =#>(integer, integer);
|
||||
DROP FUNCTION testpub_rf_func1(integer, integer);
|
||||
DROP FUNCTION testpub_rf_func2();
|
||||
@ -399,6 +411,8 @@ DROP TABLE rf_tbl_abcd_part_pk;
|
||||
-- ======================================================
|
||||
-- Tests with generated column
|
||||
SET client_min_messages = 'ERROR';
|
||||
|
||||
-- stored
|
||||
CREATE TABLE testpub_gencol (a INT, b INT GENERATED ALWAYS AS (a + 1) STORED NOT NULL);
|
||||
CREATE UNIQUE INDEX testpub_gencol_idx ON testpub_gencol (b);
|
||||
ALTER TABLE testpub_gencol REPLICA IDENTITY USING index testpub_gencol_idx;
|
||||
@ -420,6 +434,25 @@ UPDATE testpub_gencol SET a = 100 WHERE a = 1;
|
||||
DROP PUBLICATION pub_gencol;
|
||||
|
||||
DROP TABLE testpub_gencol;
|
||||
|
||||
-- virtual
|
||||
CREATE TABLE testpub_gencol (a INT, b INT GENERATED ALWAYS AS (a + 1) VIRTUAL);
|
||||
|
||||
CREATE PUBLICATION pub_gencol FOR TABLE testpub_gencol;
|
||||
|
||||
-- error - generated column "b" must be published explicitly as it is
|
||||
-- part of the REPLICA IDENTITY.
|
||||
ALTER TABLE testpub_gencol REPLICA IDENTITY FULL;
|
||||
UPDATE testpub_gencol SET a = 100 WHERE a = 1;
|
||||
DROP PUBLICATION pub_gencol;
|
||||
|
||||
-- error - "stored" setting does not affect virtual column
|
||||
CREATE PUBLICATION pub_gencol FOR TABLE testpub_gencol with (publish_generated_columns = stored);
|
||||
UPDATE testpub_gencol SET a = 100 WHERE a = 1;
|
||||
DROP PUBLICATION pub_gencol;
|
||||
|
||||
DROP TABLE testpub_gencol;
|
||||
|
||||
RESET client_min_messages;
|
||||
-- ======================================================
|
||||
|
||||
@ -435,7 +468,9 @@ CREATE PUBLICATION testpub_fortable FOR TABLE testpub_tbl1;
|
||||
CREATE PUBLICATION testpub_fortable_insert WITH (publish = 'insert');
|
||||
RESET client_min_messages;
|
||||
CREATE TABLE testpub_tbl5 (a int PRIMARY KEY, b text, c text,
|
||||
d int generated always as (a + length(b)) stored);
|
||||
d int generated always as (a + length(b)) stored,
|
||||
e int generated always as (a + length(b)) virtual
|
||||
);
|
||||
-- error: column "x" does not exist
|
||||
ALTER PUBLICATION testpub_fortable ADD TABLE testpub_tbl5 (a, x);
|
||||
-- error: replica identity "a" not included in the column list
|
||||
@ -462,9 +497,11 @@ ALTER TABLE testpub_tbl5 REPLICA IDENTITY USING INDEX testpub_tbl5_b_key;
|
||||
UPDATE testpub_tbl5 SET a = 1;
|
||||
ALTER PUBLICATION testpub_fortable DROP TABLE testpub_tbl5;
|
||||
|
||||
-- ok: generated column "d" can be in the list too
|
||||
-- ok: stored generated column "d" can be in the list too
|
||||
ALTER PUBLICATION testpub_fortable ADD TABLE testpub_tbl5 (a, d);
|
||||
ALTER PUBLICATION testpub_fortable DROP TABLE testpub_tbl5;
|
||||
-- error: virtual generated column "e" can't be in list
|
||||
ALTER PUBLICATION testpub_fortable ADD TABLE testpub_tbl5 (a, e);
|
||||
|
||||
-- error: change the replica identity to "b", and column list to (a, c)
|
||||
-- then update fails, because (a, c) does not cover replica identity
|
||||
|
@ -2072,6 +2072,33 @@ INSERT INTO r1 VALUES (10)
|
||||
|
||||
DROP TABLE r1;
|
||||
|
||||
--
|
||||
-- Test policies using virtual generated columns
|
||||
--
|
||||
SET SESSION AUTHORIZATION regress_rls_alice;
|
||||
SET row_security = on;
|
||||
CREATE TABLE r1 (a int, b int GENERATED ALWAYS AS (a * 10) VIRTUAL);
|
||||
ALTER TABLE r1 ADD c int GENERATED ALWAYS AS (a * 100) VIRTUAL;
|
||||
INSERT INTO r1 VALUES (1), (2), (4);
|
||||
|
||||
CREATE POLICY p0 ON r1 USING (b * 10 = c);
|
||||
CREATE POLICY p1 ON r1 AS RESTRICTIVE USING (b > 10);
|
||||
CREATE POLICY p2 ON r1 AS RESTRICTIVE USING ((SELECT c) < 400);
|
||||
ALTER TABLE r1 ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE r1 FORCE ROW LEVEL SECURITY;
|
||||
|
||||
-- Should fail p1
|
||||
INSERT INTO r1 VALUES (0);
|
||||
|
||||
-- Should fail p2
|
||||
INSERT INTO r1 VALUES (4);
|
||||
|
||||
-- OK
|
||||
INSERT INTO r1 VALUES (3);
|
||||
SELECT * FROM r1;
|
||||
|
||||
DROP TABLE r1;
|
||||
|
||||
-- Check dependency handling
|
||||
RESET SESSION AUTHORIZATION;
|
||||
CREATE TABLE dep1 (c1 int);
|
||||
|
@ -45,6 +45,20 @@ CREATE STATISTICS tst ON (y) FROM ext_stats_test; -- single column reference
|
||||
CREATE STATISTICS tst ON y + z FROM ext_stats_test; -- missing parentheses
|
||||
CREATE STATISTICS tst ON (x, y) FROM ext_stats_test; -- tuple expression
|
||||
DROP TABLE ext_stats_test;
|
||||
-- statistics on virtual generated column not allowed
|
||||
CREATE TABLE ext_stats_test1 (x int, y int, z int GENERATED ALWAYS AS (x+y) VIRTUAL, w xid);
|
||||
CREATE STATISTICS tst on z from ext_stats_test1;
|
||||
CREATE STATISTICS tst on (z) from ext_stats_test1;
|
||||
CREATE STATISTICS tst on (z+1) from ext_stats_test1;
|
||||
CREATE STATISTICS tst (ndistinct) ON z from ext_stats_test1;
|
||||
-- statistics on system column not allowed
|
||||
CREATE STATISTICS tst on tableoid from ext_stats_test1;
|
||||
CREATE STATISTICS tst on (tableoid) from ext_stats_test1;
|
||||
CREATE STATISTICS tst on (tableoid::int+1) from ext_stats_test1;
|
||||
CREATE STATISTICS tst (ndistinct) ON xmin from ext_stats_test1;
|
||||
-- statistics without a less-than operator not supported
|
||||
CREATE STATISTICS tst (ndistinct) ON w from ext_stats_test1;
|
||||
DROP TABLE ext_stats_test1;
|
||||
|
||||
-- Ensure stats are dropped sanely, and test IF NOT EXISTS while at it
|
||||
CREATE TABLE ab1 (a INTEGER, b INTEGER, c INTEGER);
|
||||
|
@ -21,11 +21,11 @@ $node_subscriber->start;
|
||||
my $publisher_connstr = $node_publisher->connstr . ' dbname=postgres';
|
||||
|
||||
$node_publisher->safe_psql('postgres',
|
||||
"CREATE TABLE tab1 (a int PRIMARY KEY, b int GENERATED ALWAYS AS (a * 2) STORED)"
|
||||
"CREATE TABLE tab1 (a int PRIMARY KEY, b int GENERATED ALWAYS AS (a * 2) STORED, c int GENERATED ALWAYS AS (a * 3) VIRTUAL)"
|
||||
);
|
||||
|
||||
$node_subscriber->safe_psql('postgres',
|
||||
"CREATE TABLE tab1 (a int PRIMARY KEY, b int GENERATED ALWAYS AS (a * 22) STORED, c int)"
|
||||
"CREATE TABLE tab1 (a int PRIMARY KEY, b int GENERATED ALWAYS AS (a * 22) STORED, c int GENERATED ALWAYS AS (a * 33) VIRTUAL, d int)"
|
||||
);
|
||||
|
||||
# data for initial sync
|
||||
@ -42,10 +42,11 @@ $node_subscriber->safe_psql('postgres',
|
||||
# Wait for initial sync of all subscriptions
|
||||
$node_subscriber->wait_for_subscription_sync;
|
||||
|
||||
my $result = $node_subscriber->safe_psql('postgres', "SELECT a, b FROM tab1");
|
||||
is( $result, qq(1|22
|
||||
2|44
|
||||
3|66), 'generated columns initial sync');
|
||||
my $result =
|
||||
$node_subscriber->safe_psql('postgres', "SELECT a, b, c FROM tab1");
|
||||
is( $result, qq(1|22|33
|
||||
2|44|66
|
||||
3|66|99), 'generated columns initial sync');
|
||||
|
||||
# data to replicate
|
||||
|
||||
@ -56,11 +57,11 @@ $node_publisher->safe_psql('postgres', "UPDATE tab1 SET a = 6 WHERE a = 5");
|
||||
$node_publisher->wait_for_catchup('sub1');
|
||||
|
||||
$result = $node_subscriber->safe_psql('postgres', "SELECT * FROM tab1");
|
||||
is( $result, qq(1|22|
|
||||
2|44|
|
||||
3|66|
|
||||
4|88|
|
||||
6|132|), 'generated columns replicated');
|
||||
is( $result, qq(1|22|33|
|
||||
2|44|66|
|
||||
3|66|99|
|
||||
4|88|132|
|
||||
6|132|198|), 'generated columns replicated');
|
||||
|
||||
# try it with a subscriber-side trigger
|
||||
|
||||
@ -69,7 +70,7 @@ $node_subscriber->safe_psql(
|
||||
CREATE FUNCTION tab1_trigger_func() RETURNS trigger
|
||||
LANGUAGE plpgsql AS $$
|
||||
BEGIN
|
||||
NEW.c := NEW.a + 10;
|
||||
NEW.d := NEW.a + 10;
|
||||
RETURN NEW;
|
||||
END $$;
|
||||
|
||||
@ -88,13 +89,13 @@ $node_publisher->wait_for_catchup('sub1');
|
||||
|
||||
$result =
|
||||
$node_subscriber->safe_psql('postgres', "SELECT * FROM tab1 ORDER BY 1");
|
||||
is( $result, qq(1|22|
|
||||
2|44|
|
||||
3|66|
|
||||
4|88|
|
||||
6|132|
|
||||
8|176|18
|
||||
9|198|19), 'generated columns replicated with trigger');
|
||||
is( $result, qq(1|22|33|
|
||||
2|44|66|
|
||||
3|66|99|
|
||||
4|88|132|
|
||||
6|132|198|
|
||||
8|176|264|18
|
||||
9|198|297|19), 'generated columns replicated with trigger');
|
||||
|
||||
# cleanup
|
||||
$node_subscriber->safe_psql('postgres', "DROP SUBSCRIPTION sub1");
|
||||
|
@ -240,6 +240,9 @@ $node_publisher->safe_psql('postgres',
|
||||
$node_publisher->safe_psql('postgres',
|
||||
"CREATE TABLE tab_rowfilter_child_sync PARTITION OF tab_rowfilter_parent_sync FOR VALUES FROM (1) TO (20)"
|
||||
);
|
||||
$node_publisher->safe_psql('postgres',
|
||||
"CREATE TABLE tab_rowfilter_virtual (id int PRIMARY KEY, x int, y int GENERATED ALWAYS AS (x * 2) VIRTUAL)"
|
||||
);
|
||||
|
||||
# setup structure on subscriber
|
||||
$node_subscriber->safe_psql('postgres',
|
||||
@ -294,6 +297,9 @@ $node_subscriber->safe_psql('postgres',
|
||||
"CREATE TABLE tab_rowfilter_parent_sync (a int)");
|
||||
$node_subscriber->safe_psql('postgres',
|
||||
"CREATE TABLE tab_rowfilter_child_sync (a int)");
|
||||
$node_subscriber->safe_psql('postgres',
|
||||
"CREATE TABLE tab_rowfilter_virtual (id int PRIMARY KEY, x int, y int GENERATED ALWAYS AS (x * 2) VIRTUAL)"
|
||||
);
|
||||
|
||||
# setup logical replication
|
||||
$node_publisher->safe_psql('postgres',
|
||||
@ -359,6 +365,11 @@ $node_publisher->safe_psql('postgres',
|
||||
"CREATE PUBLICATION tap_pub_child_sync FOR TABLE tab_rowfilter_child_sync WHERE (a < 15)"
|
||||
);
|
||||
|
||||
# publication using virtual generated column in row filter expression
|
||||
$node_publisher->safe_psql('postgres',
|
||||
"CREATE PUBLICATION tap_pub_virtual FOR TABLE tab_rowfilter_virtual WHERE (y > 10)"
|
||||
);
|
||||
|
||||
#
|
||||
# The following INSERTs are executed before the CREATE SUBSCRIPTION, so these
|
||||
# SQL commands are for testing the initial data copy using logical replication.
|
||||
@ -407,8 +418,12 @@ $node_publisher->safe_psql('postgres',
|
||||
"INSERT INTO tab_rowfilter_child(a, b) VALUES(0,'0'),(30,'30'),(40,'40')"
|
||||
);
|
||||
|
||||
$node_publisher->safe_psql('postgres',
|
||||
"INSERT INTO tab_rowfilter_virtual (id, x) VALUES (1, 2), (2, 4), (3, 6)"
|
||||
);
|
||||
|
||||
$node_subscriber->safe_psql('postgres',
|
||||
"CREATE SUBSCRIPTION tap_sub CONNECTION '$publisher_connstr application_name=$appname' PUBLICATION tap_pub_1, tap_pub_2, tap_pub_3, tap_pub_4a, tap_pub_4b, tap_pub_5a, tap_pub_5b, tap_pub_toast, tap_pub_inherits, tap_pub_viaroot_2, tap_pub_viaroot_1, tap_pub_parent_sync, tap_pub_child_sync"
|
||||
"CREATE SUBSCRIPTION tap_sub CONNECTION '$publisher_connstr application_name=$appname' PUBLICATION tap_pub_1, tap_pub_2, tap_pub_3, tap_pub_4a, tap_pub_4b, tap_pub_5a, tap_pub_5b, tap_pub_toast, tap_pub_inherits, tap_pub_viaroot_2, tap_pub_viaroot_1, tap_pub_parent_sync, tap_pub_child_sync, tap_pub_virtual"
|
||||
);
|
||||
|
||||
# wait for initial table synchronization to finish
|
||||
@ -550,6 +565,16 @@ $result =
|
||||
"SELECT a FROM tab_rowfilter_child_sync ORDER BY 1");
|
||||
is($result, qq(), 'check initial data copy from tab_rowfilter_child_sync');
|
||||
|
||||
# Check expected replicated rows for tab_rowfilter_virtual
|
||||
# tap_pub_virtual filter is: (y > 10), where y is generated as (x * 2)
|
||||
# - INSERT (1, 2) NO, 2 * 2 <= 10
|
||||
# - INSERT (2, 4) NO, 4 * 2 <= 10
|
||||
# - INSERT (3, 6) YES, 6 * 2 > 10
|
||||
$result = $node_subscriber->safe_psql('postgres',
|
||||
"SELECT id, x FROM tab_rowfilter_virtual ORDER BY id");
|
||||
is($result, qq(3|6),
|
||||
'check initial data copy from table tab_rowfilter_virtual');
|
||||
|
||||
# The following commands are executed after CREATE SUBSCRIPTION, so these SQL
|
||||
# commands are for testing normal logical replication behavior.
|
||||
#
|
||||
@ -582,6 +607,8 @@ $node_publisher->safe_psql('postgres',
|
||||
"INSERT INTO tab_rowfilter_child (a, b) VALUES (13, '13'), (17, '17')");
|
||||
$node_publisher->safe_psql('postgres',
|
||||
"INSERT INTO tab_rowfilter_viaroot_part (a) VALUES (14), (15), (16)");
|
||||
$node_publisher->safe_psql('postgres',
|
||||
"INSERT INTO tab_rowfilter_virtual (id, x) VALUES (4, 3), (5, 7)");
|
||||
|
||||
$node_publisher->wait_for_catchup($appname);
|
||||
|
||||
@ -725,6 +752,15 @@ is( $result, qq(16
|
||||
'check replicated rows to tab_rowfilter_inherited and tab_rowfilter_child'
|
||||
);
|
||||
|
||||
# Check expected replicated rows for tab_rowfilter_virtual
|
||||
# tap_pub_virtual filter is: (y > 10), where y is generated as (x * 2)
|
||||
# - INSERT (4, 3) NO, 3 * 2 <= 10
|
||||
# - INSERT (5, 7) YES, 7 * 2 > 10
|
||||
$result = $node_subscriber->safe_psql('postgres',
|
||||
"SELECT id, x FROM tab_rowfilter_virtual ORDER BY id");
|
||||
is( $result, qq(3|6
|
||||
5|7), 'check replicated rows to tab_rowfilter_virtual');
|
||||
|
||||
# UPDATE the non-toasted column for table tab_rowfilter_toast
|
||||
$node_publisher->safe_psql('postgres',
|
||||
"UPDATE tab_rowfilter_toast SET b = '1'");
|
||||
|
@ -1209,7 +1209,7 @@ t), 'check the number of columns in the old tuple');
|
||||
# list) are considered to have the same column list.
|
||||
$node_publisher->safe_psql(
|
||||
'postgres', qq(
|
||||
CREATE TABLE test_mix_4 (a int PRIMARY KEY, b int, c int, d int GENERATED ALWAYS AS (a + 1) STORED);
|
||||
CREATE TABLE test_mix_4 (a int PRIMARY KEY, b int, c int, d int GENERATED ALWAYS AS (a + 1) STORED, e int GENERATED ALWAYS AS (a + 2) VIRTUAL);
|
||||
ALTER TABLE test_mix_4 DROP COLUMN c;
|
||||
|
||||
CREATE PUBLICATION pub_mix_7 FOR TABLE test_mix_4 (a, b);
|
||||
|
Loading…
x
Reference in New Issue
Block a user