1
0
mirror of https://github.com/postgres/postgres.git synced 2025-06-11 20:28:21 +03:00

postgres_fdw: Fix issues with generated columns in foreign tables.

postgres_fdw imported generated columns from the remote tables as plain
columns, and caused failures like "ERROR: cannot insert a non-DEFAULT
value into column "foo"" when inserting into the foreign tables, as it
tried to insert values into the generated columns.  To fix, we do the
following under the assumption that generated columns in a postgres_fdw
foreign table are defined so that they represent generated columns in
the underlying remote table:

* Send DEFAULT for the generated columns to the foreign server on insert
  or update, not generated column values computed on the local server.
* Add to postgresImportForeignSchema() an option "import_generated" to
  include column generated expressions in the definitions of foreign
  tables imported from a foreign server.  The option is true by default.

The assumption seems reasonable, because that would make a query of the
postgres_fdw foreign table return values for the generated columns that
are consistent with the generated expression.

While here, fix another issue in postgresImportForeignSchema(): it tried
to include column generated expressions as column default expressions in
the foreign table definitions when the import_default option was enabled.

Per bug #16631 from Daniel Cherniy.  Back-patch to v12 where generated
columns were added.

Discussion: https://postgr.es/m/16631-e929fe9db0ffc7cf%40postgresql.org
This commit is contained in:
Etsuro Fujita
2021-08-05 20:00:00 +09:00
parent 93d573d865
commit aa769f80ed
6 changed files with 238 additions and 38 deletions

View File

@ -6548,13 +6548,37 @@ select * from rem1;
-- ===================================================================
-- test generated columns
-- ===================================================================
create table gloc1 (a int, b int);
create table gloc1 (
a int,
b int generated always as (a * 2) stored);
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');
explain (verbose, costs off)
insert into grem1 (a) values (1), (2);
QUERY PLAN
-------------------------------------------------------------------
Insert on public.grem1
Remote SQL: INSERT INTO public.gloc1(a, b) VALUES ($1, DEFAULT)
Batch Size: 1
-> Values Scan on "*VALUES*"
Output: "*VALUES*".column1, 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
------------------------------------------------------------------------------------
Update on public.grem1
Remote SQL: UPDATE public.gloc1 SET a = $2, b = 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
(5 rows)
update grem1 set a = 22 where a = 2;
select * from gloc1;
a | b
@ -6570,6 +6594,54 @@ select * from grem1;
22 | 44
(2 rows)
delete from grem1;
-- test copy from
copy grem1 from stdin;
select * from gloc1;
a | b
---+---
1 | 2
2 | 4
(2 rows)
select * from grem1;
a | b
---+---
1 | 2
2 | 4
(2 rows)
delete from grem1;
-- test batch insert
alter server loopback options (add batch_size '10');
explain (verbose, costs off)
insert into grem1 (a) values (1), (2);
QUERY PLAN
-------------------------------------------------------------------
Insert on public.grem1
Remote SQL: INSERT INTO public.gloc1(a, b) VALUES ($1, DEFAULT)
Batch Size: 10
-> Values Scan on "*VALUES*"
Output: "*VALUES*".column1, NULL::integer
(5 rows)
insert into grem1 (a) values (1), (2);
select * from gloc1;
a | b
---+---
1 | 2
2 | 4
(2 rows)
select * from grem1;
a | b
---+---
1 | 2
2 | 4
(2 rows)
delete from grem1;
alter server loopback options (drop batch_size);
-- ===================================================================
-- test local triggers
-- ===================================================================
@ -8656,6 +8728,7 @@ CREATE TABLE import_source.t3 (c1 timestamptz default now(), c2 typ1);
CREATE TABLE import_source."x 4" (c1 float8, "C 2" text, c3 varchar(42));
CREATE TABLE import_source."x 5" (c1 float8);
ALTER TABLE import_source."x 5" DROP COLUMN c1;
CREATE TABLE import_source."x 6" (c1 int, c2 int generated always as (c1 * 2) stored);
CREATE TABLE import_source.t4 (c1 int) PARTITION BY RANGE (c1);
CREATE TABLE import_source.t4_part PARTITION OF import_source.t4
FOR VALUES FROM (1) TO (100);
@ -8673,7 +8746,8 @@ IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest1;
import_dest1 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
import_dest1 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
import_dest1 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
(6 rows)
import_dest1 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
(7 rows)
\d import_dest1.*
Foreign table "import_dest1.t1"
@ -8723,6 +8797,14 @@ FDW options: (schema_name 'import_source', table_name 'x 4')
Server: loopback
FDW options: (schema_name 'import_source', table_name 'x 5')
Foreign table "import_dest1.x 6"
Column | Type | Collation | Nullable | Default | FDW options
--------+---------+-----------+----------+-------------------------------------+--------------------
c1 | integer | | | | (column_name 'c1')
c2 | integer | | | generated always as (c1 * 2) stored | (column_name 'c2')
Server: loopback
FDW options: (schema_name 'import_source', table_name 'x 6')
-- Options
CREATE SCHEMA import_dest2;
IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest2
@ -8737,7 +8819,8 @@ IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest2
import_dest2 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
import_dest2 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
import_dest2 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
(6 rows)
import_dest2 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
(7 rows)
\d import_dest2.*
Foreign table "import_dest2.t1"
@ -8787,9 +8870,17 @@ FDW options: (schema_name 'import_source', table_name 'x 4')
Server: loopback
FDW options: (schema_name 'import_source', table_name 'x 5')
Foreign table "import_dest2.x 6"
Column | Type | Collation | Nullable | Default | FDW options
--------+---------+-----------+----------+-------------------------------------+--------------------
c1 | integer | | | | (column_name 'c1')
c2 | integer | | | generated always as (c1 * 2) stored | (column_name 'c2')
Server: loopback
FDW options: (schema_name 'import_source', table_name 'x 6')
CREATE SCHEMA import_dest3;
IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest3
OPTIONS (import_collate 'false', import_not_null 'false');
OPTIONS (import_collate 'false', import_generated 'false', import_not_null 'false');
\det+ import_dest3.*
List of foreign tables
Schema | Table | Server | FDW options | Description
@ -8800,7 +8891,8 @@ IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest3
import_dest3 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
import_dest3 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
import_dest3 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
(6 rows)
import_dest3 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
(7 rows)
\d import_dest3.*
Foreign table "import_dest3.t1"
@ -8850,6 +8942,14 @@ FDW options: (schema_name 'import_source', table_name 'x 4')
Server: loopback
FDW options: (schema_name 'import_source', table_name 'x 5')
Foreign table "import_dest3.x 6"
Column | Type | Collation | Nullable | Default | FDW options
--------+---------+-----------+----------+---------+--------------------
c1 | integer | | | | (column_name 'c1')
c2 | integer | | | | (column_name 'c2')
Server: loopback
FDW options: (schema_name 'import_source', table_name 'x 6')
-- Check LIMIT TO and EXCEPT
CREATE SCHEMA import_dest4;
IMPORT FOREIGN SCHEMA import_source LIMIT TO (t1, nonesuch, t4_part)
@ -8874,7 +8974,8 @@ IMPORT FOREIGN SCHEMA import_source EXCEPT (t1, "x 4", nonesuch, t4_part)
import_dest4 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
import_dest4 | t4_part | loopback | (schema_name 'import_source', table_name 't4_part') |
import_dest4 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
(6 rows)
import_dest4 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
(7 rows)
-- Assorted error cases
IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest4;