INSERT INTO agg_csv VALUES(1,2.0);
UPDATE agg_csv SET a = 1;
DELETE FROM agg_csv WHERE a = 100;
--- but this should be ignored
+-- but this should be allowed
SELECT * FROM agg_csv FOR UPDATE;
-- constraint exclusion tests
SELECT * FROM agg_csv WHERE a < 0;
RESET constraint_exclusion;
+-- table inheritance tests
+CREATE TABLE agg (a int2, b float4);
+ALTER FOREIGN TABLE agg_csv INHERIT agg;
+SELECT tableoid::regclass, * FROM agg;
+SELECT tableoid::regclass, * FROM agg_csv;
+SELECT tableoid::regclass, * FROM ONLY agg;
+-- updates aren't supported
+UPDATE agg SET a = 1;
+DELETE FROM agg WHERE a = 100;
+-- but this should be allowed
+SELECT tableoid::regclass, * FROM agg FOR UPDATE;
+ALTER FOREIGN TABLE agg_csv NO INHERIT agg;
+DROP TABLE agg;
+
-- privilege tests
SET ROLE file_fdw_superuser;
SELECT * FROM agg_text ORDER BY a;
ERROR: cannot update foreign table "agg_csv"
DELETE FROM agg_csv WHERE a = 100;
ERROR: cannot delete from foreign table "agg_csv"
--- but this should be ignored
+-- but this should be allowed
SELECT * FROM agg_csv FOR UPDATE;
a | b
-----+---------
(0 rows)
RESET constraint_exclusion;
+-- table inheritance tests
+CREATE TABLE agg (a int2, b float4);
+ALTER FOREIGN TABLE agg_csv INHERIT agg;
+SELECT tableoid::regclass, * FROM agg;
+ tableoid | a | b
+----------+-----+---------
+ agg_csv | 100 | 99.097
+ agg_csv | 0 | 0.09561
+ agg_csv | 42 | 324.78
+(3 rows)
+
+SELECT tableoid::regclass, * FROM agg_csv;
+ tableoid | a | b
+----------+-----+---------
+ agg_csv | 100 | 99.097
+ agg_csv | 0 | 0.09561
+ agg_csv | 42 | 324.78
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY agg;
+ tableoid | a | b
+----------+---+---
+(0 rows)
+
+-- updates aren't supported
+UPDATE agg SET a = 1;
+ERROR: cannot update foreign table "agg_csv"
+DELETE FROM agg WHERE a = 100;
+ERROR: cannot delete from foreign table "agg_csv"
+-- but this should be allowed
+SELECT tableoid::regclass, * FROM agg FOR UPDATE;
+ tableoid | a | b
+----------+-----+---------
+ agg_csv | 100 | 99.097
+ agg_csv | 0 | 0.09561
+ agg_csv | 42 | 324.78
+(3 rows)
+
+ALTER FOREIGN TABLE agg_csv NO INHERIT agg;
+DROP TABLE agg;
-- privilege tests
SET ROLE file_fdw_superuser;
SELECT * FROM agg_text ORDER BY a;
(0,27)
(1 row)
+-- ===================================================================
+-- test inheritance features
+-- ===================================================================
+CREATE TABLE a (aa TEXT);
+CREATE TABLE loct (aa TEXT, bb TEXT);
+CREATE FOREIGN TABLE b (bb TEXT) INHERITS (a)
+ SERVER loopback OPTIONS (table_name 'loct');
+INSERT INTO a(aa) VALUES('aaa');
+INSERT INTO a(aa) VALUES('aaaa');
+INSERT INTO a(aa) VALUES('aaaaa');
+INSERT INTO b(aa) VALUES('bbb');
+INSERT INTO b(aa) VALUES('bbbb');
+INSERT INTO b(aa) VALUES('bbbbb');
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+-------
+ a | aaa
+ a | aaaa
+ a | aaaaa
+ b | bbb
+ b | bbbb
+ b | bbbbb
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-------+----
+ b | bbb |
+ b | bbbb |
+ b | bbbbb |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+-------
+ a | aaa
+ a | aaaa
+ a | aaaaa
+(3 rows)
+
+UPDATE a SET aa = 'zzzzzz' WHERE aa LIKE 'aaaa%';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+ b | bbb
+ b | bbbb
+ b | bbbbb
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-------+----
+ b | bbb |
+ b | bbbb |
+ b | bbbbb |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+(3 rows)
+
+UPDATE b SET aa = 'new';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+ b | new
+ b | new
+ b | new
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-----+----
+ b | new |
+ b | new |
+ b | new |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+(3 rows)
+
+UPDATE a SET aa = 'newtoo';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | newtoo
+ a | newtoo
+ a | newtoo
+ b | newtoo
+ b | newtoo
+ b | newtoo
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+--------+----
+ b | newtoo |
+ b | newtoo |
+ b | newtoo |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | newtoo
+ a | newtoo
+ a | newtoo
+(3 rows)
+
+DELETE FROM a;
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+----
+(0 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+----+----
+(0 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+----
+(0 rows)
+
+DROP TABLE a CASCADE;
+NOTICE: drop cascades to foreign table b
+DROP TABLE loct;
+-- Check SELECT FOR UPDATE/SHARE with an inherited source table
+create table loct1 (f1 int, f2 int, f3 int);
+create table loct2 (f1 int, f2 int, f3 int);
+create table foo (f1 int, f2 int);
+create foreign table foo2 (f3 int) inherits (foo)
+ server loopback options (table_name 'loct1');
+create table bar (f1 int, f2 int);
+create foreign table bar2 (f3 int) inherits (bar)
+ server loopback options (table_name 'loct2');
+insert into foo values(1,1);
+insert into foo values(3,3);
+insert into foo2 values(2,2,2);
+insert into foo2 values(4,4,4);
+insert into bar values(1,11);
+insert into bar values(2,22);
+insert into bar values(6,66);
+insert into bar2 values(3,33,33);
+insert into bar2 values(4,44,44);
+insert into bar2 values(7,77,77);
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo) for update;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, bar.tableoid, bar.*, foo.ctid, foo.tableoid, foo.*
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, bar.tableoid, bar.*, foo.ctid, foo.tableoid, foo.*
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar
+ Output: bar.f1, bar.f2, bar.ctid, bar.tableoid, bar.*
+ -> Foreign Scan on public.bar2
+ Output: bar2.f1, bar2.f2, bar2.ctid, bar2.tableoid, bar2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Hash
+ Output: foo.ctid, foo.tableoid, foo.*, foo.f1
+ -> HashAggregate
+ Output: foo.ctid, foo.tableoid, foo.*, foo.f1
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo
+ Output: foo.ctid, foo.tableoid, foo.*, foo.f1
+ -> Foreign Scan on public.foo2
+ Output: foo2.ctid, foo2.tableoid, foo2.*, foo2.f1
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(22 rows)
+
+select * from bar where f1 in (select f1 from foo) for update;
+ f1 | f2
+----+----
+ 1 | 11
+ 2 | 22
+ 3 | 33
+ 4 | 44
+(4 rows)
+
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo) for share;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, bar.tableoid, bar.*, foo.ctid, foo.tableoid, foo.*
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, bar.tableoid, bar.*, foo.ctid, foo.tableoid, foo.*
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar
+ Output: bar.f1, bar.f2, bar.ctid, bar.tableoid, bar.*
+ -> Foreign Scan on public.bar2
+ Output: bar2.f1, bar2.f2, bar2.ctid, bar2.tableoid, bar2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo.ctid, foo.tableoid, foo.*, foo.f1
+ -> HashAggregate
+ Output: foo.ctid, foo.tableoid, foo.*, foo.f1
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo
+ Output: foo.ctid, foo.tableoid, foo.*, foo.f1
+ -> Foreign Scan on public.foo2
+ Output: foo2.ctid, foo2.tableoid, foo2.*, foo2.f1
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(22 rows)
+
+select * from bar where f1 in (select f1 from foo) for share;
+ f1 | f2
+----+----
+ 1 | 11
+ 2 | 22
+ 3 | 33
+ 4 | 44
+(4 rows)
+
+-- Check UPDATE with inherited target and an inherited source table
+explain (verbose, costs off)
+update bar set f2 = f2 + 100 where f1 in (select f1 from foo);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar
+ Foreign Update on public.bar2
+ Remote SQL: UPDATE public.loct2 SET f2 = $2 WHERE ctid = $1
+ -> Hash Join
+ Output: bar.f1, (bar.f2 + 100), bar.ctid, foo.ctid, foo.tableoid, foo.*
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Seq Scan on public.bar
+ Output: bar.f1, bar.f2, bar.ctid
+ -> Hash
+ Output: foo.ctid, foo.tableoid, foo.*, foo.f1
+ -> HashAggregate
+ Output: foo.ctid, foo.tableoid, foo.*, foo.f1
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo
+ Output: foo.ctid, foo.tableoid, foo.*, foo.f1
+ -> Foreign Scan on public.foo2
+ Output: foo2.ctid, foo2.tableoid, foo2.*, foo2.f1
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+ -> Hash Join
+ Output: bar2.f1, (bar2.f2 + 100), bar2.f3, bar2.ctid, foo.ctid, foo.tableoid, foo.*
+ Hash Cond: (bar2.f1 = foo.f1)
+ -> Foreign Scan on public.bar2
+ Output: bar2.f1, bar2.f2, bar2.f3, bar2.ctid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Hash
+ Output: foo.ctid, foo.tableoid, foo.*, foo.f1
+ -> HashAggregate
+ Output: foo.ctid, foo.tableoid, foo.*, foo.f1
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo
+ Output: foo.ctid, foo.tableoid, foo.*, foo.f1
+ -> Foreign Scan on public.foo2
+ Output: foo2.ctid, foo2.tableoid, foo2.*, foo2.f1
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(37 rows)
+
+update bar set f2 = f2 + 100 where f1 in (select f1 from foo);
+select tableoid::regclass, * from bar order by 1,2;
+ tableoid | f1 | f2
+----------+----+-----
+ bar | 1 | 111
+ bar | 2 | 122
+ bar | 6 | 66
+ bar2 | 3 | 133
+ bar2 | 4 | 144
+ bar2 | 7 | 77
+(6 rows)
+
+-- Check UPDATE with inherited target and an appendrel subquery
+explain (verbose, costs off)
+update bar set f2 = f2 + 100
+from
+ ( select f1 from foo union all select f1+3 from foo ) ss
+where bar.f1 = ss.f1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar
+ Foreign Update on public.bar2
+ Remote SQL: UPDATE public.loct2 SET f2 = $2 WHERE ctid = $1
+ -> Hash Join
+ Output: bar.f1, (bar.f2 + 100), bar.ctid, (ROW(foo.f1))
+ Hash Cond: (foo.f1 = bar.f1)
+ -> Append
+ -> Seq Scan on public.foo
+ Output: ROW(foo.f1), foo.f1
+ -> Foreign Scan on public.foo2
+ Output: ROW(foo2.f1), foo2.f1
+ Remote SQL: SELECT f1 FROM public.loct1
+ -> Seq Scan on public.foo foo_1
+ Output: ROW((foo_1.f1 + 3)), (foo_1.f1 + 3)
+ -> Foreign Scan on public.foo2 foo2_1
+ Output: ROW((foo2_1.f1 + 3)), (foo2_1.f1 + 3)
+ Remote SQL: SELECT f1 FROM public.loct1
+ -> Hash
+ Output: bar.f1, bar.f2, bar.ctid
+ -> Seq Scan on public.bar
+ Output: bar.f1, bar.f2, bar.ctid
+ -> Merge Join
+ Output: bar2.f1, (bar2.f2 + 100), bar2.f3, bar2.ctid, (ROW(foo.f1))
+ Merge Cond: (bar2.f1 = foo.f1)
+ -> Sort
+ Output: bar2.f1, bar2.f2, bar2.f3, bar2.ctid
+ Sort Key: bar2.f1
+ -> Foreign Scan on public.bar2
+ Output: bar2.f1, bar2.f2, bar2.f3, bar2.ctid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Sort
+ Output: (ROW(foo.f1)), foo.f1
+ Sort Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo
+ Output: ROW(foo.f1), foo.f1
+ -> Foreign Scan on public.foo2
+ Output: ROW(foo2.f1), foo2.f1
+ Remote SQL: SELECT f1 FROM public.loct1
+ -> Seq Scan on public.foo foo_1
+ Output: ROW((foo_1.f1 + 3)), (foo_1.f1 + 3)
+ -> Foreign Scan on public.foo2 foo2_1
+ Output: ROW((foo2_1.f1 + 3)), (foo2_1.f1 + 3)
+ Remote SQL: SELECT f1 FROM public.loct1
+(45 rows)
+
+update bar set f2 = f2 + 100
+from
+ ( select f1 from foo union all select f1+3 from foo ) ss
+where bar.f1 = ss.f1;
+select tableoid::regclass, * from bar order by 1,2;
+ tableoid | f1 | f2
+----------+----+-----
+ bar | 1 | 211
+ bar | 2 | 222
+ bar | 6 | 166
+ bar2 | 3 | 233
+ bar2 | 4 | 244
+ bar2 | 7 | 177
+(6 rows)
+
+-- Test that WHERE CURRENT OF is not supported
+begin;
+declare c cursor for select * from bar where f1 = 7;
+fetch from c;
+ f1 | f2
+----+-----
+ 7 | 177
+(1 row)
+
+update bar set f2 = null where current of c;
+ERROR: WHERE CURRENT OF is not supported for this table type
+rollback;
+drop table foo cascade;
+NOTICE: drop cascades to foreign table foo2
+drop table bar cascade;
+NOTICE: drop cascades to foreign table bar2
+drop table loct1;
+drop table loct2;
-- ===================================================================
-- test IMPORT FOREIGN SCHEMA
-- ===================================================================
-- Test returning a system attribute
INSERT INTO rem1(f2) VALUES ('test') RETURNING ctid;
+-- ===================================================================
+-- test inheritance features
+-- ===================================================================
+
+CREATE TABLE a (aa TEXT);
+CREATE TABLE loct (aa TEXT, bb TEXT);
+CREATE FOREIGN TABLE b (bb TEXT) INHERITS (a)
+ SERVER loopback OPTIONS (table_name 'loct');
+
+INSERT INTO a(aa) VALUES('aaa');
+INSERT INTO a(aa) VALUES('aaaa');
+INSERT INTO a(aa) VALUES('aaaaa');
+
+INSERT INTO b(aa) VALUES('bbb');
+INSERT INTO b(aa) VALUES('bbbb');
+INSERT INTO b(aa) VALUES('bbbbb');
+
+SELECT tableoid::regclass, * FROM a;
+SELECT tableoid::regclass, * FROM b;
+SELECT tableoid::regclass, * FROM ONLY a;
+
+UPDATE a SET aa = 'zzzzzz' WHERE aa LIKE 'aaaa%';
+
+SELECT tableoid::regclass, * FROM a;
+SELECT tableoid::regclass, * FROM b;
+SELECT tableoid::regclass, * FROM ONLY a;
+
+UPDATE b SET aa = 'new';
+
+SELECT tableoid::regclass, * FROM a;
+SELECT tableoid::regclass, * FROM b;
+SELECT tableoid::regclass, * FROM ONLY a;
+
+UPDATE a SET aa = 'newtoo';
+
+SELECT tableoid::regclass, * FROM a;
+SELECT tableoid::regclass, * FROM b;
+SELECT tableoid::regclass, * FROM ONLY a;
+
+DELETE FROM a;
+
+SELECT tableoid::regclass, * FROM a;
+SELECT tableoid::regclass, * FROM b;
+SELECT tableoid::regclass, * FROM ONLY a;
+
+DROP TABLE a CASCADE;
+DROP TABLE loct;
+
+-- Check SELECT FOR UPDATE/SHARE with an inherited source table
+create table loct1 (f1 int, f2 int, f3 int);
+create table loct2 (f1 int, f2 int, f3 int);
+
+create table foo (f1 int, f2 int);
+create foreign table foo2 (f3 int) inherits (foo)
+ server loopback options (table_name 'loct1');
+create table bar (f1 int, f2 int);
+create foreign table bar2 (f3 int) inherits (bar)
+ server loopback options (table_name 'loct2');
+
+insert into foo values(1,1);
+insert into foo values(3,3);
+insert into foo2 values(2,2,2);
+insert into foo2 values(4,4,4);
+insert into bar values(1,11);
+insert into bar values(2,22);
+insert into bar values(6,66);
+insert into bar2 values(3,33,33);
+insert into bar2 values(4,44,44);
+insert into bar2 values(7,77,77);
+
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo) for update;
+select * from bar where f1 in (select f1 from foo) for update;
+
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo) for share;
+select * from bar where f1 in (select f1 from foo) for share;
+
+-- Check UPDATE with inherited target and an inherited source table
+explain (verbose, costs off)
+update bar set f2 = f2 + 100 where f1 in (select f1 from foo);
+update bar set f2 = f2 + 100 where f1 in (select f1 from foo);
+
+select tableoid::regclass, * from bar order by 1,2;
+
+-- Check UPDATE with inherited target and an appendrel subquery
+explain (verbose, costs off)
+update bar set f2 = f2 + 100
+from
+ ( select f1 from foo union all select f1+3 from foo ) ss
+where bar.f1 = ss.f1;
+update bar set f2 = f2 + 100
+from
+ ( select f1 from foo union all select f1+3 from foo ) ss
+where bar.f1 = ss.f1;
+
+select tableoid::regclass, * from bar order by 1,2;
+
+-- Test that WHERE CURRENT OF is not supported
+begin;
+declare c cursor for select * from bar where f1 = 7;
+fetch from c;
+update bar set f2 = null where current of c;
+rollback;
+
+drop table foo cascade;
+drop table bar cascade;
+drop table loct1;
+drop table loct2;
+
-- ===================================================================
-- test IMPORT FOREIGN SCHEMA
-- ===================================================================
<para>
Adding a unique constraint will automatically create a unique btree
- index on the column or group of columns used in the constraint.
+ index on the column or group of columns used in the constraint.
A uniqueness constraint on only some rows can be enforced by creating
a <link linkend="indexes-partial">partial index</link>.
</para>
</programlisting>
</para>
+ <para>
+ Another way to get the same effect is to use the <type>regclass</>
+ pseudo-type, which will print the table OID symbolically:
+
+<programlisting>
+SELECT c.tableoid::regclass, c.name, c.altitude
+FROM cities c
+WHERE c.altitude > 500;
+</programlisting>
+ </para>
+
<para>
Inheritance does not automatically propagate data from
<command>INSERT</command> or <command>COPY</command> commands to
further privileges to be granted.
</para>
+ <para>
+ Foreign tables (see <xref linkend="ddl-foreign-data">) can also
+ be part of inheritance hierarchies, either as parent or child
+ tables, just as regular tables can be. If a foreign table is part
+ of an inheritance hierarchy then any operations not supported by
+ the foreign table are not supported on the whole hierarchy either.
+ </para>
+
<sect2 id="ddl-inherit-caveats">
<title>Caveats</title>
<para>
We will refer to the child tables as partitions, though they
- are in every way normal <productname>PostgreSQL</> tables.
+ are in every way normal <productname>PostgreSQL</> tables
+ (or, possibly, foreign tables).
</para>
</listitem>
decisions.
</para>
+ <para>
+ When an <command>UPDATE</> or <command>DELETE</> command affects an
+ inheritance hierarchy, the output might look like this:
+
+<screen>
+EXPLAIN UPDATE parent SET f2 = f2 + 1 WHERE f1 = 101;
+ QUERY PLAN
+-----------------------------------------------------------------------------------
+ Update on parent (cost=0.00..24.53 rows=4 width=14)
+ Update on parent
+ Update on child1
+ Update on child2
+ Update on child3
+ -> Seq Scan on parent (cost=0.00..0.00 rows=1 width=14)
+ Filter: (f1 = 101)
+ -> Index Scan using child1_f1_key on child1 (cost=0.15..8.17 rows=1 width=14)
+ Index Cond: (f1 = 101)
+ -> Index Scan using child2_f1_key on child2 (cost=0.15..8.17 rows=1 width=14)
+ Index Cond: (f1 = 101)
+ -> Index Scan using child3_f1_key on child3 (cost=0.15..8.17 rows=1 width=14)
+ Index Cond: (f1 = 101)
+</screen>
+
+ In this example the Update node needs to consider three child tables as
+ well as the originally-mentioned parent table. So there are four input
+ scanning subplans, one per table. For clarity, the Update node is
+ annotated to show the specific target tables that will be updated, in the
+ same order as the corresponding subplans. (These annotations are new as
+ of <productname>PostgreSQL</> 9.5; in prior versions the reader had to
+ intuit the target tables by inspecting the subplans.)
+ </para>
+
<para>
The <literal>Planning time</literal> shown by <command>EXPLAIN
ANALYZE</command> is the time it took to generate the query plan from the
<refsynopsisdiv>
<synopsis>
-ALTER FOREIGN TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable>
+ALTER FOREIGN TABLE [ IF EXISTS ] [ ONLY ] <replaceable class="PARAMETER">name</replaceable> [ * ]
<replaceable class="PARAMETER">action</replaceable> [, ... ]
-ALTER FOREIGN TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable>
+ALTER FOREIGN TABLE [ IF EXISTS ] [ ONLY ] <replaceable class="PARAMETER">name</replaceable> [ * ]
RENAME [ COLUMN ] <replaceable class="PARAMETER">column_name</replaceable> TO <replaceable class="PARAMETER">new_column_name</replaceable>
ALTER FOREIGN TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable>
RENAME TO <replaceable class="PARAMETER">new_name</replaceable>
ADD [ COLUMN ] <replaceable class="PARAMETER">column_name</replaceable> <replaceable class="PARAMETER">data_type</replaceable> [ COLLATE <replaceable class="PARAMETER">collation</replaceable> ] [ <replaceable class="PARAMETER">column_constraint</replaceable> [ ... ] ]
DROP [ COLUMN ] [ IF EXISTS ] <replaceable class="PARAMETER">column_name</replaceable> [ RESTRICT | CASCADE ]
- ALTER [ COLUMN ] <replaceable class="PARAMETER">column_name</replaceable> [ SET DATA ] TYPE <replaceable class="PARAMETER">data_type</replaceable>
+ ALTER [ COLUMN ] <replaceable class="PARAMETER">column_name</replaceable> [ SET DATA ] TYPE <replaceable class="PARAMETER">data_type</replaceable> [ COLLATE <replaceable class="PARAMETER">collation</replaceable> ]
ALTER [ COLUMN ] <replaceable class="PARAMETER">column_name</replaceable> SET DEFAULT <replaceable class="PARAMETER">expression</replaceable>
ALTER [ COLUMN ] <replaceable class="PARAMETER">column_name</replaceable> DROP DEFAULT
ALTER [ COLUMN ] <replaceable class="PARAMETER">column_name</replaceable> { SET | DROP } NOT NULL
ALTER [ COLUMN ] <replaceable class="PARAMETER">column_name</replaceable> SET STATISTICS <replaceable class="PARAMETER">integer</replaceable>
ALTER [ COLUMN ] <replaceable class="PARAMETER">column_name</replaceable> SET ( <replaceable class="PARAMETER">attribute_option</replaceable> = <replaceable class="PARAMETER">value</replaceable> [, ... ] )
ALTER [ COLUMN ] <replaceable class="PARAMETER">column_name</replaceable> RESET ( <replaceable class="PARAMETER">attribute_option</replaceable> [, ... ] )
+ ALTER [ COLUMN ] <replaceable class="PARAMETER">column_name</replaceable> SET STORAGE { PLAIN | EXTERNAL | EXTENDED | MAIN }
ALTER [ COLUMN ] <replaceable class="PARAMETER">column_name</replaceable> OPTIONS ( [ ADD | SET | DROP ] <replaceable class="PARAMETER">option</replaceable> ['<replaceable class="PARAMETER">value</replaceable>'] [, ... ])
- ADD <replaceable class="PARAMETER">table_constraint</replaceable>
+ ADD <replaceable class="PARAMETER">table_constraint</replaceable> [ NOT VALID ]
+ VALIDATE CONSTRAINT <replaceable class="PARAMETER">constraint_name</replaceable>
DROP CONSTRAINT [ IF EXISTS ] <replaceable class="PARAMETER">constraint_name</replaceable> [ RESTRICT | CASCADE ]
DISABLE TRIGGER [ <replaceable class="PARAMETER">trigger_name</replaceable> | ALL | USER ]
ENABLE TRIGGER [ <replaceable class="PARAMETER">trigger_name</replaceable> | ALL | USER ]
ENABLE REPLICA TRIGGER <replaceable class="PARAMETER">trigger_name</replaceable>
ENABLE ALWAYS TRIGGER <replaceable class="PARAMETER">trigger_name</replaceable>
+ SET WITH OIDS
+ SET WITHOUT OIDS
+ INHERIT <replaceable class="PARAMETER">parent_table</replaceable>
+ NO INHERIT <replaceable class="PARAMETER">parent_table</replaceable>
OWNER TO { <replaceable class="PARAMETER">new_owner</replaceable> | CURRENT_USER | SESSION_USER }
OPTIONS ( [ ADD | SET | DROP ] <replaceable class="PARAMETER">option</replaceable> ['<replaceable class="PARAMETER">value</replaceable>'] [, ... ])
</synopsis>
<listitem>
<para>
This form changes the type of a column of a foreign table.
+ Again, this has no effect on any underlying storage: this action simply
+ changes the type that <productname>PostgreSQL</> believes the column to
+ have.
</para>
</listitem>
</varlistentry>
</varlistentry>
<varlistentry>
- <term><literal>ADD <replaceable class="PARAMETER">table_constraint</replaceable></literal></term>
+ <term>
+ <literal>SET STORAGE</literal>
+ </term>
+ <listitem>
+ <para>
+ This form sets the storage mode for a column.
+ See the similar form of <xref linkend="sql-altertable">
+ for more details.
+ Note that the storage mode has no effect unless the table's
+ foreign-data wrapper chooses to pay attention to it.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><literal>ADD <replaceable class="PARAMETER">table_constraint</replaceable></literal> [ NOT VALID ]</term>
<listitem>
<para>
This form adds a new constraint to a foreign table, using the same
<para>
Unlike the case when adding a constraint to a regular table, nothing is
done to verify the constraint is correct; rather, this action simply
- declares that some new condition holds for all rows in the foreign
- table. (See the discussion in <xref linkend="SQL-CREATEFOREIGNTABLE">.)
- Note that constraints on foreign tables cannot be marked
- <literal>NOT VALID</> since such constraints are simply declarative.
+ declares that some new condition should be assumed to hold for all rows
+ in the foreign table. (See the discussion
+ in <xref linkend="SQL-CREATEFOREIGNTABLE">.)
+ If the constraint is marked <literal>NOT VALID</>, then it isn't
+ assumed to hold, but is only recorded for possible future use.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><literal>VALIDATE CONSTRAINT</literal></term>
+ <listitem>
+ <para>
+ This form marks as valid a constraint that was previously marked
+ as <literal>NOT VALID</literal>. No action is taken to verify the
+ constraint, but future queries will assume that it holds.
</para>
</listitem>
</varlistentry>
</listitem>
</varlistentry>
+ <varlistentry>
+ <term><literal>SET WITH OIDS</literal></term>
+ <listitem>
+ <para>
+ This form adds an <literal>oid</literal> system column to the
+ table (see <xref linkend="ddl-system-columns">).
+ It does nothing if the table already has OIDs.
+ Unless the table's foreign-data wrapper supports OIDs, this column
+ will simply read as zeroes.
+ </para>
+
+ <para>
+ Note that this is not equivalent to <literal>ADD COLUMN oid oid</>;
+ that would add a normal column that happened to be named
+ <literal>oid</>, not a system column.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><literal>SET WITHOUT OIDS</literal></term>
+ <listitem>
+ <para>
+ This form removes the <literal>oid</literal> system column from the
+ table. This is exactly equivalent to
+ <literal>DROP COLUMN oid RESTRICT</literal>,
+ except that it will not complain if there is already no
+ <literal>oid</literal> column.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><literal>INHERIT <replaceable class="PARAMETER">parent_table</replaceable></literal></term>
+ <listitem>
+ <para>
+ This form adds the target foreign table as a new child of the specified
+ parent table.
+ See the similar form of <xref linkend="sql-altertable">
+ for more details.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><literal>NO INHERIT <replaceable class="PARAMETER">parent_table</replaceable></literal></term>
+ <listitem>
+ <para>
+ This form removes the target foreign table from the list of children of
+ the specified parent table.
+ </para>
+ </listitem>
+ </varlistentry>
+
<varlistentry>
<term><literal>OWNER</literal></term>
<listitem>
<listitem>
<para>
The name (possibly schema-qualified) of an existing foreign table to
- alter.
+ alter. If <literal>ONLY</> is specified before the table name, only
+ that table is altered. If <literal>ONLY</> is not specified, the table
+ and all its descendant tables (if any) are altered. Optionally,
+ <literal>*</> can be specified after the table name to explicitly
+ indicate that descendant tables are included.
</para>
</listitem>
</varlistentry>
</listitem>
</varlistentry>
+ <varlistentry>
+ <term><replaceable class="PARAMETER">parent_table</replaceable></term>
+ <listitem>
+ <para>
+ A parent table to associate or de-associate with this foreign table.
+ </para>
+ </listitem>
+ </varlistentry>
+
<varlistentry>
<term><replaceable class="PARAMETER">new_owner</replaceable></term>
<listitem>
run <command>ANALYZE</command> manually.
</para>
+ <para>
+ If any of the child tables are foreign tables whose foreign data wrappers
+ do not support <command>ANALYZE</>, those child tables are ignored while
+ gathering inheritance statistics.
+ </para>
+
<para>
If the table being analyzed is completely empty, <command>ANALYZE</command>
will not record new statistics for that table. Any existing statistics
| <replaceable>table_constraint</replaceable> }
[, ... ]
] )
+[ INHERITS ( <replaceable>parent_table</replaceable> [, ... ] ) ]
SERVER <replaceable class="parameter">server_name</replaceable>
[ OPTIONS ( <replaceable class="PARAMETER">option</replaceable> '<replaceable class="PARAMETER">value</replaceable>' [, ... ] ) ]
</listitem>
</varlistentry>
+ <varlistentry>
+ <term><literal>COLLATE <replaceable>collation</replaceable></literal></term>
+ <listitem>
+ <para>
+ The <literal>COLLATE</> clause assigns a collation to
+ the column (which must be of a collatable data type).
+ If not specified, the column data type's default collation is used.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><literal>INHERITS ( <replaceable>parent_table</replaceable> [, ... ] )</literal></term>
+ <listitem>
+ <para>
+ The optional <literal>INHERITS</> clause specifies a list of
+ tables from which the new foreign table automatically inherits
+ all columns. Parent tables can be plain tables or foreign tables.
+ See the similar form of
+ <xref linkend="sql-createtable"> for more details.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><literal>CONSTRAINT <replaceable class="PARAMETER">constraint_name</replaceable></literal></term>
+ <listitem>
+ <para>
+ An optional name for a column or table constraint. If the
+ constraint is violated, the constraint name is present in error messages,
+ so constraint names like <literal>col must be positive</> can be used
+ to communicate helpful constraint information to client applications.
+ (Double-quotes are needed to specify constraint names that contain spaces.)
+ If a constraint name is not specified, the system generates a name.
+ </para>
+ </listitem>
+ </varlistentry>
+
<varlistentry>
<term><literal>NOT NULL</></term>
<listitem>
</varlistentry>
<varlistentry>
- <term><literal>CHECK ( <replaceable class="PARAMETER">expression</replaceable> )</literal></term>
+ <term><literal>CHECK ( <replaceable class="PARAMETER">expression</replaceable> ) [ NO INHERIT ] </literal></term>
<listitem>
<para>
The <literal>CHECK</> clause specifies an expression producing a
current row. The system column <literal>tableoid</literal>
may be referenced, but not any other system column.
</para>
+
+ <para>
+ A constraint marked with <literal>NO INHERIT</> will not propagate to
+ child tables.
+ </para>
</listitem>
</varlistentry>
<acronym>SQL</acronym> standard; however, much as with
<link linkend="sql-createtable"><command>CREATE TABLE</></link>,
<literal>NULL</> constraints and zero-column foreign tables are permitted.
- The ability to specify a default value is also a <productname>PostgreSQL</>
- extension.
+ The ability to specify column default values is also
+ a <productname>PostgreSQL</> extension. Table inheritance, in the form
+ defined by <productname>PostgreSQL</productname>, is nonstandard.
</para>
</refsect1>
<para>
The optional <literal>INHERITS</> clause specifies a list of
tables from which the new table automatically inherits all
- columns.
+ columns. Parent tables can be plain tables or foreign tables.
</para>
<para>
error will be reported.
</para>
- <para><literal>CHECK</> constraints are merged in essentially the same way as
+ <para>
+ <literal>CHECK</> constraints are merged in essentially the same way as
columns: if multiple parent tables and/or the new table definition
contain identically-named <literal>CHECK</> constraints, these
constraints must all have the same check expression, or an error will be
This is similar to the usual behavior of <function>currval()</> after
a failed transaction.
</para>
+
+ <para>
+ <command>TRUNCATE</> is not currently supported for foreign tables.
+ This implies that if a specified table has any descendant tables that are
+ foreign, the command will fail.
+ </para>
</refsect1>
<refsect1>
expr = stringToNode(cdef->cooked_expr);
}
- /* Don't allow NOT VALID for foreign tables */
- if (cdef->skip_validation &&
- rel->rd_rel->relkind == RELKIND_FOREIGN_TABLE)
- ereport(ERROR,
- (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
- errmsg("CHECK constraints on foreign tables cannot be marked NOT VALID")));
-
/*
* Check name uniqueness, or generate a name if none was given.
*/
* do_analyze_rel() -- analyze one relation, recursively or not
*
* Note that "acquirefunc" is only relevant for the non-inherited case.
- * If we supported foreign tables in inheritance trees,
- * acquire_inherited_sample_rows would need to determine the appropriate
- * acquirefunc for each child table.
+ * For the inherited case, acquire_inherited_sample_rows() determines the
+ * appropriate acquirefunc for each child table.
*/
static void
do_analyze_rel(Relation onerel, int options, List *va_cols,
*
* This has the same API as acquire_sample_rows, except that rows are
* collected from all inheritance children as well as the specified table.
- * We fail and return zero if there are no inheritance children.
+ * We fail and return zero if there are no inheritance children, or if all
+ * children are foreign tables that don't support ANALYZE.
*/
static int
acquire_inherited_sample_rows(Relation onerel, int elevel,
{
List *tableOIDs;
Relation *rels;
+ AcquireSampleRowsFunc *acquirefuncs;
double *relblocks;
double totalblocks;
int numrows,
}
/*
- * Count the blocks in all the relations. The result could overflow
- * BlockNumber, so we use double arithmetic.
+ * Identify acquirefuncs to use, and count blocks in all the relations.
+ * The result could overflow BlockNumber, so we use double arithmetic.
*/
rels = (Relation *) palloc(list_length(tableOIDs) * sizeof(Relation));
+ acquirefuncs = (AcquireSampleRowsFunc *)
+ palloc(list_length(tableOIDs) * sizeof(AcquireSampleRowsFunc));
relblocks = (double *) palloc(list_length(tableOIDs) * sizeof(double));
totalblocks = 0;
nrels = 0;
{
Oid childOID = lfirst_oid(lc);
Relation childrel;
+ AcquireSampleRowsFunc acquirefunc = NULL;
+ BlockNumber relpages = 0;
/* We already got the needed lock */
childrel = heap_open(childOID, NoLock);
continue;
}
+ /* Check table type (MATVIEW can't happen, but might as well allow) */
+ if (childrel->rd_rel->relkind == RELKIND_RELATION ||
+ childrel->rd_rel->relkind == RELKIND_MATVIEW)
+ {
+ /* Regular table, so use the regular row acquisition function */
+ acquirefunc = acquire_sample_rows;
+ relpages = RelationGetNumberOfBlocks(childrel);
+ }
+ else if (childrel->rd_rel->relkind == RELKIND_FOREIGN_TABLE)
+ {
+ /*
+ * For a foreign table, call the FDW's hook function to see
+ * whether it supports analysis.
+ */
+ FdwRoutine *fdwroutine;
+ bool ok = false;
+
+ fdwroutine = GetFdwRoutineForRelation(childrel, false);
+
+ if (fdwroutine->AnalyzeForeignTable != NULL)
+ ok = fdwroutine->AnalyzeForeignTable(childrel,
+ &acquirefunc,
+ &relpages);
+
+ if (!ok)
+ {
+ /* ignore, but release the lock on it */
+ Assert(childrel != onerel);
+ heap_close(childrel, AccessShareLock);
+ continue;
+ }
+ }
+ else
+ {
+ /* ignore, but release the lock on it */
+ Assert(childrel != onerel);
+ heap_close(childrel, AccessShareLock);
+ continue;
+ }
+
+ /* OK, we'll process this child */
rels[nrels] = childrel;
- relblocks[nrels] = (double) RelationGetNumberOfBlocks(childrel);
- totalblocks += relblocks[nrels];
+ acquirefuncs[nrels] = acquirefunc;
+ relblocks[nrels] = (double) relpages;
+ totalblocks += (double) relpages;
nrels++;
}
+ /*
+ * If we don't have at least two tables to consider, fail.
+ */
+ if (nrels < 2)
+ {
+ ereport(elevel,
+ (errmsg("skipping analyze of \"%s.%s\" inheritance tree --- this inheritance tree contains no analyzable child tables",
+ get_namespace_name(RelationGetNamespace(onerel)),
+ RelationGetRelationName(onerel))));
+ return 0;
+ }
+
/*
* Now sample rows from each relation, proportionally to its fraction of
* the total block count. (This might be less than desirable if the child
for (i = 0; i < nrels; i++)
{
Relation childrel = rels[i];
+ AcquireSampleRowsFunc acquirefunc = acquirefuncs[i];
double childblocks = relblocks[i];
if (childblocks > 0)
tdrows;
/* Fetch a random sample of the child's rows */
- childrows = acquire_sample_rows(childrel,
- elevel,
- rows + numrows,
- childtargrows,
- &trows,
- &tdrows);
+ childrows = (*acquirefunc) (childrel, elevel,
+ rows + numrows, childtargrows,
+ &trows, &tdrows);
/* We may need to convert from child's rowtype to parent's */
if (childrows > 0 &&
/*
* Show the target of a ModifyTable node
+ *
+ * Here we show the nominal target (ie, the relation that was named in the
+ * original query). If the actual target(s) is/are different, we'll show them
+ * in show_modifytable_info().
*/
static void
ExplainModifyTarget(ModifyTable *plan, ExplainState *es)
/*
* Show extra information for a ModifyTable node
+ *
+ * We have two objectives here. First, if there's more than one target table
+ * or it's different from the nominal target, identify the actual target(s).
+ * Second, give FDWs a chance to display extra info about foreign targets.
*/
static void
show_modifytable_info(ModifyTableState *mtstate, ExplainState *es)
{
- FdwRoutine *fdwroutine = mtstate->resultRelInfo->ri_FdwRoutine;
+ ModifyTable *node = (ModifyTable *) mtstate->ps.plan;
+ const char *operation;
+ const char *foperation;
+ bool labeltargets;
+ int j;
- /*
- * If the first target relation is a foreign table, call its FDW to
- * display whatever additional fields it wants to. For now, we ignore the
- * possibility of other targets being foreign tables, although the API for
- * ExplainForeignModify is designed to allow them to be processed.
- */
- if (fdwroutine != NULL &&
- fdwroutine->ExplainForeignModify != NULL)
+ switch (node->operation)
{
- ModifyTable *node = (ModifyTable *) mtstate->ps.plan;
- List *fdw_private = (List *) linitial(node->fdwPrivLists);
-
- fdwroutine->ExplainForeignModify(mtstate,
- mtstate->resultRelInfo,
- fdw_private,
- 0,
- es);
+ case CMD_INSERT:
+ operation = "Insert";
+ foperation = "Foreign Insert";
+ break;
+ case CMD_UPDATE:
+ operation = "Update";
+ foperation = "Foreign Update";
+ break;
+ case CMD_DELETE:
+ operation = "Delete";
+ foperation = "Foreign Delete";
+ break;
+ default:
+ operation = "???";
+ foperation = "Foreign ???";
+ break;
+ }
+
+ /* Should we explicitly label target relations? */
+ labeltargets = (mtstate->mt_nplans > 1 ||
+ (mtstate->mt_nplans == 1 &&
+ mtstate->resultRelInfo->ri_RangeTableIndex != node->nominalRelation));
+
+ if (labeltargets)
+ ExplainOpenGroup("Target Tables", "Target Tables", false, es);
+
+ for (j = 0; j < mtstate->mt_nplans; j++)
+ {
+ ResultRelInfo *resultRelInfo = mtstate->resultRelInfo + j;
+ FdwRoutine *fdwroutine = resultRelInfo->ri_FdwRoutine;
+
+ if (labeltargets)
+ {
+ /* Open a group for this target */
+ ExplainOpenGroup("Target Table", NULL, true, es);
+
+ /*
+ * In text mode, decorate each target with operation type, so that
+ * ExplainTargetRel's output of " on foo" will read nicely.
+ */
+ if (es->format == EXPLAIN_FORMAT_TEXT)
+ {
+ appendStringInfoSpaces(es->str, es->indent * 2);
+ appendStringInfoString(es->str,
+ fdwroutine ? foperation : operation);
+ }
+
+ /* Identify target */
+ ExplainTargetRel((Plan *) node,
+ resultRelInfo->ri_RangeTableIndex,
+ es);
+
+ if (es->format == EXPLAIN_FORMAT_TEXT)
+ {
+ appendStringInfoChar(es->str, '\n');
+ es->indent++;
+ }
+ }
+
+ /* Give FDW a chance */
+ if (fdwroutine && fdwroutine->ExplainForeignModify != NULL)
+ {
+ List *fdw_private = (List *) list_nth(node->fdwPrivLists, j);
+
+ fdwroutine->ExplainForeignModify(mtstate,
+ resultRelInfo,
+ fdw_private,
+ j,
+ es);
+ }
+
+ if (labeltargets)
+ {
+ /* Undo the indentation we added in text format */
+ if (es->format == EXPLAIN_FORMAT_TEXT)
+ es->indent--;
+
+ /* Close the group */
+ ExplainCloseGroup("Target Table", NULL, true, es);
+ }
}
+
+ if (labeltargets)
+ ExplainCloseGroup("Target Tables", "Target Tables", false, es);
}
/*
*/
relation = heap_openrv(parent, ShareUpdateExclusiveLock);
- if (relation->rd_rel->relkind != RELKIND_RELATION)
+ if (relation->rd_rel->relkind != RELKIND_RELATION &&
+ relation->rd_rel->relkind != RELKIND_FOREIGN_TABLE)
ereport(ERROR,
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
- errmsg("inherited relation \"%s\" is not a table",
+ errmsg("inherited relation \"%s\" is not a table or foreign table",
parent->relname)));
/* Permanent rels cannot inherit from temporary ones */
if (relpersistence != RELPERSISTENCE_TEMP &&
pass = AT_PASS_MISC;
break;
case AT_SetStorage: /* ALTER COLUMN SET STORAGE */
- ATSimplePermissions(rel, ATT_TABLE | ATT_MATVIEW);
+ ATSimplePermissions(rel, ATT_TABLE | ATT_MATVIEW | ATT_FOREIGN_TABLE);
ATSimpleRecursion(wqueue, rel, cmd, recurse, lockmode);
/* No command-specific prep needed */
pass = AT_PASS_MISC;
pass = AT_PASS_MISC;
break;
case AT_AddOids: /* SET WITH OIDS */
- ATSimplePermissions(rel, ATT_TABLE);
+ ATSimplePermissions(rel, ATT_TABLE | ATT_FOREIGN_TABLE);
if (!rel->rd_rel->relhasoids || recursing)
ATPrepAddOids(wqueue, rel, recurse, cmd, lockmode);
/* Recursion occurs during execution phase */
pass = AT_PASS_ADD_COL;
break;
case AT_DropOids: /* SET WITHOUT OIDS */
- ATSimplePermissions(rel, ATT_TABLE);
+ ATSimplePermissions(rel, ATT_TABLE | ATT_FOREIGN_TABLE);
/* Performs own recursion */
if (rel->rd_rel->relhasoids)
{
pass = AT_PASS_MISC;
break;
case AT_AddInherit: /* INHERIT */
- ATSimplePermissions(rel, ATT_TABLE);
+ ATSimplePermissions(rel, ATT_TABLE | ATT_FOREIGN_TABLE);
/* This command never recurses */
ATPrepAddInherit(rel);
pass = AT_PASS_MISC;
break;
+ case AT_DropInherit: /* NO INHERIT */
+ ATSimplePermissions(rel, ATT_TABLE | ATT_FOREIGN_TABLE);
+ /* This command never recurses */
+ /* No command-specific prep needed */
+ pass = AT_PASS_MISC;
+ break;
case AT_AlterConstraint: /* ALTER CONSTRAINT */
ATSimplePermissions(rel, ATT_TABLE);
pass = AT_PASS_MISC;
break;
case AT_ValidateConstraint: /* VALIDATE CONSTRAINT */
- ATSimplePermissions(rel, ATT_TABLE);
+ ATSimplePermissions(rel, ATT_TABLE | ATT_FOREIGN_TABLE);
/* Recursion occurs during execution phase */
/* No command-specific prep needed except saving recurse flag */
if (recurse)
case AT_EnableAlwaysRule:
case AT_EnableReplicaRule:
case AT_DisableRule:
- case AT_DropInherit: /* NO INHERIT */
case AT_AddOf: /* OF */
case AT_DropOf: /* NOT OF */
case AT_EnableRowSecurity:
/* At top level, permission check was done in ATPrepCmd, else do it */
if (recursing)
- ATSimplePermissions(rel, ATT_TABLE);
+ ATSimplePermissions(rel, ATT_TABLE | ATT_FOREIGN_TABLE);
attrdesc = heap_open(AttributeRelationId, RowExclusiveLock);
/* At top level, permission check was done in ATPrepCmd, else do it */
if (recursing)
- ATSimplePermissions(rel, ATT_TABLE);
+ ATSimplePermissions(rel, ATT_TABLE | ATT_FOREIGN_TABLE);
/*
* get the number of the attribute
/* At top level, permission check was done in ATPrepCmd, else do it */
if (recursing)
- ATSimplePermissions(rel, ATT_TABLE);
+ ATSimplePermissions(rel, ATT_TABLE | ATT_FOREIGN_TABLE);
/*
* Call AddRelationNewConstraints to do the work, making sure it works on
bool isnull;
Snapshot snapshot;
+ /* VALIDATE CONSTRAINT is a no-op for foreign tables */
+ if (rel->rd_rel->relkind == RELKIND_FOREIGN_TABLE)
+ return;
+
constrForm = (Form_pg_constraint) GETSTRUCT(constrtup);
estate = CreateExecutorState();
/* At top level, permission check was done in ATPrepCmd, else do it */
if (recursing)
- ATSimplePermissions(rel, ATT_TABLE);
+ ATSimplePermissions(rel, ATT_TABLE | ATT_FOREIGN_TABLE);
conrel = heap_open(ConstraintRelationId, RowExclusiveLock);
* Must be owner of both parent and child -- child was checked by
* ATSimplePermissions call in ATPrepCmd
*/
- ATSimplePermissions(parent_rel, ATT_TABLE);
+ ATSimplePermissions(parent_rel, ATT_TABLE | ATT_FOREIGN_TABLE);
/* Permanent rels cannot inherit from temporary ones */
if (parent_rel->rd_rel->relpersistence == RELPERSISTENCE_TEMP &&
if (!RowMarkRequiresRowShareLock(thiserm->markType))
continue; /* ignore non-FOR UPDATE/SHARE items */
- if (RelationGetRelid(thiserm->relation) == table_oid)
+ if (thiserm->relid == table_oid)
{
if (erm)
ereport(ERROR,
if (rc->isParent)
continue;
+ /* get relation's OID (will produce InvalidOid if subquery) */
+ relid = getrelid(rc->rti, rangeTable);
+
switch (rc->markType)
{
case ROW_MARK_EXCLUSIVE:
case ROW_MARK_NOKEYEXCLUSIVE:
case ROW_MARK_SHARE:
case ROW_MARK_KEYSHARE:
- relid = getrelid(rc->rti, rangeTable);
relation = heap_open(relid, RowShareLock);
break;
case ROW_MARK_REFERENCE:
- relid = getrelid(rc->rti, rangeTable);
relation = heap_open(relid, AccessShareLock);
break;
case ROW_MARK_COPY:
- /* there's no real table here ... */
+ /* no physical table access is required */
relation = NULL;
break;
default:
erm = (ExecRowMark *) palloc(sizeof(ExecRowMark));
erm->relation = relation;
+ erm->relid = relid;
erm->rti = rc->rti;
erm->prti = rc->prti;
erm->rowmarkId = rc->rowmarkId;
aerm->rowmark = erm;
/* Look up the resjunk columns associated with this rowmark */
- if (erm->relation)
+ if (erm->markType != ROW_MARK_COPY)
{
- Assert(erm->markType != ROW_MARK_COPY);
-
- /* if child rel, need tableoid */
- if (erm->rti != erm->prti)
- {
- snprintf(resname, sizeof(resname), "tableoid%u", erm->rowmarkId);
- aerm->toidAttNo = ExecFindJunkAttributeInTlist(targetlist,
- resname);
- if (!AttributeNumberIsValid(aerm->toidAttNo))
- elog(ERROR, "could not find junk %s column", resname);
- }
-
- /* always need ctid for real relations */
+ /* need ctid for all methods other than COPY */
snprintf(resname, sizeof(resname), "ctid%u", erm->rowmarkId);
aerm->ctidAttNo = ExecFindJunkAttributeInTlist(targetlist,
resname);
}
else
{
- Assert(erm->markType == ROW_MARK_COPY);
-
+ /* need wholerow if COPY */
snprintf(resname, sizeof(resname), "wholerow%u", erm->rowmarkId);
aerm->wholeAttNo = ExecFindJunkAttributeInTlist(targetlist,
resname);
elog(ERROR, "could not find junk %s column", resname);
}
+ /* if child rel, need tableoid */
+ if (erm->rti != erm->prti)
+ {
+ snprintf(resname, sizeof(resname), "tableoid%u", erm->rowmarkId);
+ aerm->toidAttNo = ExecFindJunkAttributeInTlist(targetlist,
+ resname);
+ if (!AttributeNumberIsValid(aerm->toidAttNo))
+ elog(ERROR, "could not find junk %s column", resname);
+ }
+
return aerm;
}
/* clear any leftover test tuple for this rel */
EvalPlanQualSetTuple(epqstate, erm->rti, NULL);
- if (erm->relation)
+ /* if child rel, must check whether it produced this row */
+ if (erm->rti != erm->prti)
{
- Buffer buffer;
+ Oid tableoid;
- Assert(erm->markType == ROW_MARK_REFERENCE);
+ datum = ExecGetJunkAttribute(epqstate->origslot,
+ aerm->toidAttNo,
+ &isNull);
+ /* non-locked rels could be on the inside of outer joins */
+ if (isNull)
+ continue;
+ tableoid = DatumGetObjectId(datum);
- /* if child rel, must check whether it produced this row */
- if (erm->rti != erm->prti)
+ Assert(OidIsValid(erm->relid));
+ if (tableoid != erm->relid)
{
- Oid tableoid;
+ /* this child is inactive right now */
+ continue;
+ }
+ }
- datum = ExecGetJunkAttribute(epqstate->origslot,
- aerm->toidAttNo,
- &isNull);
- /* non-locked rels could be on the inside of outer joins */
- if (isNull)
- continue;
- tableoid = DatumGetObjectId(datum);
+ if (erm->markType == ROW_MARK_REFERENCE)
+ {
+ Buffer buffer;
- if (tableoid != RelationGetRelid(erm->relation))
- {
- /* this child is inactive right now */
- continue;
- }
- }
+ Assert(erm->relation != NULL);
/* fetch the tuple's ctid */
datum = ExecGetJunkAttribute(epqstate->origslot,
tuple.t_len = HeapTupleHeaderGetDatumLength(td);
ItemPointerSetInvalid(&(tuple.t_self));
/* relation might be a foreign table, if so provide tableoid */
- tuple.t_tableOid = getrelid(erm->rti,
- epqstate->estate->es_range_table);
+ tuple.t_tableOid = erm->relid;
tuple.t_data = td;
/* copy and store tuple */
elog(ERROR, "tableoid is NULL");
tableoid = DatumGetObjectId(datum);
- if (tableoid != RelationGetRelid(erm->relation))
+ Assert(OidIsValid(erm->relid));
+ if (tableoid != erm->relid)
{
/* this child is inactive right now */
ItemPointerSetInvalid(&(erm->curCtid));
}
/* updated, so fetch and lock the updated version */
- copyTuple = EvalPlanQualFetch(estate, erm->relation, lockmode,
- erm->waitPolicy, &hufd.ctid, hufd.xmax);
+ copyTuple = EvalPlanQualFetch(estate, erm->relation,
+ lockmode, erm->waitPolicy,
+ &hufd.ctid, hufd.xmax);
if (copyTuple == NULL)
{
newrc = makeNode(PlanRowMark);
newrc->rti = newrc->prti = rc->rti;
newrc->rowmarkId = ++(root->glob->lastRowMarkId);
- if (rte->relkind == RELKIND_FOREIGN_TABLE)
- {
- /* For now, we force all foreign tables to use ROW_MARK_COPY */
- newrc->markType = ROW_MARK_COPY;
- }
- else
- {
- /* regular table, apply the appropriate lock type */
- switch (rc->strength)
- {
- case LCS_NONE:
- /* we intentionally throw an error for LCS_NONE */
- elog(ERROR, "unrecognized LockClauseStrength %d",
- (int) rc->strength);
- break;
- case LCS_FORKEYSHARE:
- newrc->markType = ROW_MARK_KEYSHARE;
- break;
- case LCS_FORSHARE:
- newrc->markType = ROW_MARK_SHARE;
- break;
- case LCS_FORNOKEYUPDATE:
- newrc->markType = ROW_MARK_NOKEYEXCLUSIVE;
- break;
- case LCS_FORUPDATE:
- newrc->markType = ROW_MARK_EXCLUSIVE;
- break;
- }
- }
+ newrc->markType = select_rowmark_type(rte, rc->strength);
newrc->allMarkTypes = (1 << newrc->markType);
newrc->strength = rc->strength;
newrc->waitPolicy = rc->waitPolicy;
newrc = makeNode(PlanRowMark);
newrc->rti = newrc->prti = i;
newrc->rowmarkId = ++(root->glob->lastRowMarkId);
- /* real tables support REFERENCE, anything else needs COPY */
- if (rte->rtekind == RTE_RELATION &&
- rte->relkind != RELKIND_FOREIGN_TABLE)
- newrc->markType = ROW_MARK_REFERENCE;
- else
- newrc->markType = ROW_MARK_COPY;
+ newrc->markType = select_rowmark_type(rte, LCS_NONE);
newrc->allMarkTypes = (1 << newrc->markType);
newrc->strength = LCS_NONE;
newrc->waitPolicy = LockWaitBlock; /* doesn't matter */
root->rowMarks = prowmarks;
}
+/*
+ * Select RowMarkType to use for a given table
+ */
+RowMarkType
+select_rowmark_type(RangeTblEntry *rte, LockClauseStrength strength)
+{
+ if (rte->rtekind != RTE_RELATION)
+ {
+ /* If it's not a table at all, use ROW_MARK_COPY */
+ return ROW_MARK_COPY;
+ }
+ else if (rte->relkind == RELKIND_FOREIGN_TABLE)
+ {
+ /* For now, we force all foreign tables to use ROW_MARK_COPY */
+ return ROW_MARK_COPY;
+ }
+ else
+ {
+ /* Regular table, apply the appropriate lock type */
+ switch (strength)
+ {
+ case LCS_NONE:
+ /* don't need tuple lock, only ability to re-fetch the row */
+ return ROW_MARK_REFERENCE;
+ break;
+ case LCS_FORKEYSHARE:
+ return ROW_MARK_KEYSHARE;
+ break;
+ case LCS_FORSHARE:
+ return ROW_MARK_SHARE;
+ break;
+ case LCS_FORNOKEYUPDATE:
+ return ROW_MARK_NOKEYEXCLUSIVE;
+ break;
+ case LCS_FORUPDATE:
+ return ROW_MARK_EXCLUSIVE;
+ break;
+ }
+ elog(ERROR, "unrecognized LockClauseStrength %d", (int) strength);
+ return ROW_MARK_EXCLUSIVE; /* keep compiler quiet */
+ }
+}
+
/*
* preprocess_limit - do pre-estimation for LIMIT and/or OFFSET clauses
*
/*
* Build an RTE for the child, and attach to query's rangetable list.
- * We copy most fields of the parent's RTE, but replace relation OID,
- * and set inh = false. Also, set requiredPerms to zero since all
- * required permissions checks are done on the original RTE.
+ * We copy most fields of the parent's RTE, but replace relation OID
+ * and relkind, and set inh = false. Also, set requiredPerms to zero
+ * since all required permissions checks are done on the original RTE.
*/
childrte = copyObject(rte);
childrte->relid = childOID;
+ childrte->relkind = newrelation->rd_rel->relkind;
childrte->inh = false;
childrte->requiredPerms = 0;
parse->rtable = lappend(parse->rtable, childrte);
newrc->rti = childRTindex;
newrc->prti = rti;
newrc->rowmarkId = oldrc->rowmarkId;
- newrc->markType = oldrc->markType;
+ /* Reselect rowmark type, because relkind might not match parent */
+ newrc->markType = select_rowmark_type(childrte, oldrc->strength);
newrc->allMarkTypes = (1 << newrc->markType);
newrc->strength = oldrc->strength;
newrc->waitPolicy = oldrc->waitPolicy;
n->relation = $4;
n->tableElts = $6;
n->inhRelations = $8;
+ n->ofTypename = NULL;
n->constraints = NIL;
n->options = $9;
n->oncommit = $10;
n->relation = $7;
n->tableElts = $9;
n->inhRelations = $11;
+ n->ofTypename = NULL;
n->constraints = NIL;
n->options = $12;
n->oncommit = $13;
$4->relpersistence = $2;
n->relation = $4;
n->tableElts = $7;
+ n->inhRelations = NIL;
n->ofTypename = makeTypeNameFromNameList($6);
n->ofTypename->location = @6;
n->constraints = NIL;
$7->relpersistence = $2;
n->relation = $7;
n->tableElts = $10;
+ n->inhRelations = NIL;
n->ofTypename = makeTypeNameFromNameList($9);
n->ofTypename->location = @9;
n->constraints = NIL;
CreateForeignTableStmt:
CREATE FOREIGN TABLE qualified_name
'(' OptTableElementList ')'
- SERVER name create_generic_options
+ OptInherit SERVER name create_generic_options
{
CreateForeignTableStmt *n = makeNode(CreateForeignTableStmt);
$4->relpersistence = RELPERSISTENCE_PERMANENT;
n->base.relation = $4;
n->base.tableElts = $6;
- n->base.inhRelations = NIL;
+ n->base.inhRelations = $8;
+ n->base.ofTypename = NULL;
+ n->base.constraints = NIL;
+ n->base.options = NIL;
+ n->base.oncommit = ONCOMMIT_NOOP;
+ n->base.tablespacename = NULL;
n->base.if_not_exists = false;
/* FDW-specific data */
- n->servername = $9;
- n->options = $10;
+ n->servername = $10;
+ n->options = $11;
$$ = (Node *) n;
}
| CREATE FOREIGN TABLE IF_P NOT EXISTS qualified_name
'(' OptTableElementList ')'
- SERVER name create_generic_options
+ OptInherit SERVER name create_generic_options
{
CreateForeignTableStmt *n = makeNode(CreateForeignTableStmt);
$7->relpersistence = RELPERSISTENCE_PERMANENT;
n->base.relation = $7;
n->base.tableElts = $9;
- n->base.inhRelations = NIL;
+ n->base.inhRelations = $11;
+ n->base.ofTypename = NULL;
+ n->base.constraints = NIL;
+ n->base.options = NIL;
+ n->base.oncommit = ONCOMMIT_NOOP;
+ n->base.tablespacename = NULL;
n->base.if_not_exists = true;
/* FDW-specific data */
- n->servername = $12;
- n->options = $13;
+ n->servername = $13;
+ n->options = $14;
$$ = (Node *) n;
}
;
* attislocal correctly, plus fix up any inherited CHECK constraints.
* Analogously, we set up typed tables using ALTER TABLE / OF here.
*/
- if (dopt->binary_upgrade && (tbinfo->relkind == RELKIND_RELATION ||
- tbinfo->relkind == RELKIND_FOREIGN_TABLE))
+ if (dopt->binary_upgrade &&
+ (tbinfo->relkind == RELKIND_RELATION ||
+ tbinfo->relkind == RELKIND_FOREIGN_TABLE))
{
for (j = 0; j < tbinfo->numatts; j++)
{
appendPQExpBuffer(q, "ALTER TABLE ONLY %s ",
fmtId(tbinfo->dobj.name));
else
- appendPQExpBuffer(q, "ALTER FOREIGN TABLE %s ",
+ appendPQExpBuffer(q, "ALTER FOREIGN TABLE ONLY %s ",
fmtId(tbinfo->dobj.name));
-
appendPQExpBuffer(q, "DROP COLUMN %s;\n",
fmtId(tbinfo->attnames[j]));
}
else if (!tbinfo->attislocal[j])
{
- Assert(tbinfo->relkind != RELKIND_FOREIGN_TABLE);
appendPQExpBufferStr(q, "\n-- For binary upgrade, recreate inherited column.\n");
appendPQExpBufferStr(q, "UPDATE pg_catalog.pg_attribute\n"
"SET attislocal = false\n"
/*
* dump properties we only have ALTER TABLE syntax for
*/
- if ((tbinfo->relkind == RELKIND_RELATION || tbinfo->relkind == RELKIND_MATVIEW) &&
+ if ((tbinfo->relkind == RELKIND_RELATION ||
+ tbinfo->relkind == RELKIND_MATVIEW) &&
tbinfo->relreplident != REPLICA_IDENTITY_DEFAULT)
{
if (tbinfo->relreplident == REPLICA_IDENTITY_INDEX)
}
}
+ if (tbinfo->relkind == RELKIND_FOREIGN_TABLE && tbinfo->hasoids)
+ appendPQExpBuffer(q, "\nALTER TABLE ONLY %s SET WITH OIDS;\n",
+ fmtId(tbinfo->dobj.name));
+
if (dopt->binary_upgrade)
binary_upgrade_extension_member(q, &tbinfo->dobj, labelq->data);
* ExecRowMark -
* runtime representation of FOR [KEY] UPDATE/SHARE clauses
*
- * When doing UPDATE, DELETE, or SELECT FOR [KEY] UPDATE/SHARE, we should have an
+ * When doing UPDATE, DELETE, or SELECT FOR [KEY] UPDATE/SHARE, we will have an
* ExecRowMark for each non-target relation in the query (except inheritance
- * parent RTEs, which can be ignored at runtime). See PlanRowMark for details
- * about most of the fields. In addition to fields directly derived from
- * PlanRowMark, we store curCtid, which is used by the WHERE CURRENT OF code.
+ * parent RTEs, which can be ignored at runtime). Virtual relations such as
+ * subqueries-in-FROM will have an ExecRowMark with relation == NULL. See
+ * PlanRowMark for details about most of the fields. In addition to fields
+ * directly derived from PlanRowMark, we store curCtid, which is used by the
+ * WHERE CURRENT OF code.
*
* EState->es_rowMarks is a list of these structs.
*/
typedef struct ExecRowMark
{
Relation relation; /* opened and suitably locked relation */
+ Oid relid; /* its OID (or InvalidOid, if subquery) */
Index rti; /* its range table index */
Index prti; /* parent range table index, if child */
Index rowmarkId; /* unique identifier for resjunk columns */
extern bool is_dummy_plan(Plan *plan);
+extern RowMarkType select_rowmark_type(RangeTblEntry *rte,
+ LockClauseStrength strength);
+
extern Expr *expression_planner(Expr *expr);
extern Expr *preprocess_phv_expression(PlannerInfo *root, Expr *expr);
ALTER FOREIGN TABLE ft1 ALTER COLUMN c1 SET STATISTICS 10000;
ALTER FOREIGN TABLE ft1 ALTER COLUMN c1 SET (n_distinct = 100);
ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 SET STATISTICS -1;
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 SET STORAGE PLAIN;
\d+ ft1
Foreign table "public.ft1"
Column | Type | Modifiers | FDW Options | Storage | Stats target | Description
c5 | integer | | | plain | |
c6 | integer | not null | | plain | |
c7 | integer | | (p1 'v1', p2 'v2') | plain | |
- c8 | text | | (p2 'V2') | extended | |
+ c8 | text | | (p2 'V2') | plain | |
c9 | integer | | | plain | |
c10 | integer | | (p1 'v1') | plain | |
Check constraints:
ERROR: primary key constraints are not supported on foreign tables
LINE 1: ALTER FOREIGN TABLE ft1 ADD PRIMARY KEY (c7);
^
-ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c9_check CHECK (c9 < 0) NOT VALID; -- ERROR
-ERROR: CHECK constraints on foreign tables cannot be marked NOT VALID
-ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c9_check CHECK (c9 < 0);
+ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c9_check CHECK (c9 < 0) NOT VALID;
ALTER FOREIGN TABLE ft1 ALTER CONSTRAINT ft1_c9_check DEFERRABLE; -- ERROR
ERROR: "ft1" is not a table
ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c9_check;
ERROR: constraint "no_const" of relation "ft1" does not exist
ALTER FOREIGN TABLE ft1 DROP CONSTRAINT IF EXISTS no_const;
NOTICE: constraint "no_const" of relation "ft1" does not exist, skipping
-ALTER FOREIGN TABLE ft1 SET WITH OIDS; -- ERROR
-ERROR: "ft1" is not a table
+ALTER FOREIGN TABLE ft1 SET WITH OIDS;
ALTER FOREIGN TABLE ft1 OWNER TO regress_test_role;
ALTER FOREIGN TABLE ft1 OPTIONS (DROP delimiter, SET quote '~', ADD escape '@');
ALTER FOREIGN TABLE ft1 DROP COLUMN no_column; -- ERROR
DROP TRIGGER trigtest_after_stmt ON foreign_schema.foreign_table_1;
DROP TRIGGER trigtest_after_row ON foreign_schema.foreign_table_1;
DROP FUNCTION dummy_trigger();
+-- Table inheritance
+CREATE TABLE pt1 (
+ c1 integer NOT NULL,
+ c2 text,
+ c3 date
+);
+CREATE FOREIGN TABLE ft2 () INHERITS (pt1)
+ SERVER s0 OPTIONS (delimiter ',', quote '"', "be quoted" 'value');
+\d+ pt1
+ Table "public.pt1"
+ Column | Type | Modifiers | Storage | Stats target | Description
+--------+---------+-----------+----------+--------------+-------------
+ c1 | integer | not null | plain | |
+ c2 | text | | extended | |
+ c3 | date | | plain | |
+Child tables: ft2
+
+\d+ ft2
+ Foreign table "public.ft2"
+ Column | Type | Modifiers | FDW Options | Storage | Stats target | Description
+--------+---------+-----------+-------------+----------+--------------+-------------
+ c1 | integer | not null | | plain | |
+ c2 | text | | | extended | |
+ c3 | date | | | plain | |
+Server: s0
+FDW Options: (delimiter ',', quote '"', "be quoted" 'value')
+Inherits: pt1
+
+DROP FOREIGN TABLE ft2;
+\d+ pt1
+ Table "public.pt1"
+ Column | Type | Modifiers | Storage | Stats target | Description
+--------+---------+-----------+----------+--------------+-------------
+ c1 | integer | not null | plain | |
+ c2 | text | | extended | |
+ c3 | date | | plain | |
+
+CREATE FOREIGN TABLE ft2 (
+ c1 integer NOT NULL,
+ c2 text,
+ c3 date
+) SERVER s0 OPTIONS (delimiter ',', quote '"', "be quoted" 'value');
+\d+ ft2
+ Foreign table "public.ft2"
+ Column | Type | Modifiers | FDW Options | Storage | Stats target | Description
+--------+---------+-----------+-------------+----------+--------------+-------------
+ c1 | integer | not null | | plain | |
+ c2 | text | | | extended | |
+ c3 | date | | | plain | |
+Server: s0
+FDW Options: (delimiter ',', quote '"', "be quoted" 'value')
+
+ALTER FOREIGN TABLE ft2 INHERIT pt1;
+\d+ pt1
+ Table "public.pt1"
+ Column | Type | Modifiers | Storage | Stats target | Description
+--------+---------+-----------+----------+--------------+-------------
+ c1 | integer | not null | plain | |
+ c2 | text | | extended | |
+ c3 | date | | plain | |
+Child tables: ft2
+
+\d+ ft2
+ Foreign table "public.ft2"
+ Column | Type | Modifiers | FDW Options | Storage | Stats target | Description
+--------+---------+-----------+-------------+----------+--------------+-------------
+ c1 | integer | not null | | plain | |
+ c2 | text | | | extended | |
+ c3 | date | | | plain | |
+Server: s0
+FDW Options: (delimiter ',', quote '"', "be quoted" 'value')
+Inherits: pt1
+
+CREATE TABLE ct3() INHERITS(ft2);
+CREATE FOREIGN TABLE ft3 (
+ c1 integer NOT NULL,
+ c2 text,
+ c3 date
+) INHERITS(ft2)
+ SERVER s0;
+NOTICE: merging column "c1" with inherited definition
+NOTICE: merging column "c2" with inherited definition
+NOTICE: merging column "c3" with inherited definition
+\d+ ft2
+ Foreign table "public.ft2"
+ Column | Type | Modifiers | FDW Options | Storage | Stats target | Description
+--------+---------+-----------+-------------+----------+--------------+-------------
+ c1 | integer | not null | | plain | |
+ c2 | text | | | extended | |
+ c3 | date | | | plain | |
+Server: s0
+FDW Options: (delimiter ',', quote '"', "be quoted" 'value')
+Inherits: pt1
+Child tables: ct3,
+ ft3
+
+\d+ ct3
+ Table "public.ct3"
+ Column | Type | Modifiers | Storage | Stats target | Description
+--------+---------+-----------+----------+--------------+-------------
+ c1 | integer | not null | plain | |
+ c2 | text | | extended | |
+ c3 | date | | plain | |
+Inherits: ft2
+
+\d+ ft3
+ Foreign table "public.ft3"
+ Column | Type | Modifiers | FDW Options | Storage | Stats target | Description
+--------+---------+-----------+-------------+----------+--------------+-------------
+ c1 | integer | not null | | plain | |
+ c2 | text | | | extended | |
+ c3 | date | | | plain | |
+Server: s0
+Inherits: ft2
+
+-- add attributes recursively
+ALTER TABLE pt1 ADD COLUMN c4 integer;
+ALTER TABLE pt1 ADD COLUMN c5 integer DEFAULT 0;
+ALTER TABLE pt1 ADD COLUMN c6 integer;
+ALTER TABLE pt1 ADD COLUMN c7 integer NOT NULL;
+ALTER TABLE pt1 ADD COLUMN c8 integer;
+\d+ pt1
+ Table "public.pt1"
+ Column | Type | Modifiers | Storage | Stats target | Description
+--------+---------+-----------+----------+--------------+-------------
+ c1 | integer | not null | plain | |
+ c2 | text | | extended | |
+ c3 | date | | plain | |
+ c4 | integer | | plain | |
+ c5 | integer | default 0 | plain | |
+ c6 | integer | | plain | |
+ c7 | integer | not null | plain | |
+ c8 | integer | | plain | |
+Child tables: ft2
+
+\d+ ft2
+ Foreign table "public.ft2"
+ Column | Type | Modifiers | FDW Options | Storage | Stats target | Description
+--------+---------+-----------+-------------+----------+--------------+-------------
+ c1 | integer | not null | | plain | |
+ c2 | text | | | extended | |
+ c3 | date | | | plain | |
+ c4 | integer | | | plain | |
+ c5 | integer | default 0 | | plain | |
+ c6 | integer | | | plain | |
+ c7 | integer | not null | | plain | |
+ c8 | integer | | | plain | |
+Server: s0
+FDW Options: (delimiter ',', quote '"', "be quoted" 'value')
+Inherits: pt1
+Child tables: ct3,
+ ft3
+
+\d+ ct3
+ Table "public.ct3"
+ Column | Type | Modifiers | Storage | Stats target | Description
+--------+---------+-----------+----------+--------------+-------------
+ c1 | integer | not null | plain | |
+ c2 | text | | extended | |
+ c3 | date | | plain | |
+ c4 | integer | | plain | |
+ c5 | integer | default 0 | plain | |
+ c6 | integer | | plain | |
+ c7 | integer | not null | plain | |
+ c8 | integer | | plain | |
+Inherits: ft2
+
+\d+ ft3
+ Foreign table "public.ft3"
+ Column | Type | Modifiers | FDW Options | Storage | Stats target | Description
+--------+---------+-----------+-------------+----------+--------------+-------------
+ c1 | integer | not null | | plain | |
+ c2 | text | | | extended | |
+ c3 | date | | | plain | |
+ c4 | integer | | | plain | |
+ c5 | integer | default 0 | | plain | |
+ c6 | integer | | | plain | |
+ c7 | integer | not null | | plain | |
+ c8 | integer | | | plain | |
+Server: s0
+Inherits: ft2
+
+-- alter attributes recursively
+ALTER TABLE pt1 ALTER COLUMN c4 SET DEFAULT 0;
+ALTER TABLE pt1 ALTER COLUMN c5 DROP DEFAULT;
+ALTER TABLE pt1 ALTER COLUMN c6 SET NOT NULL;
+ALTER TABLE pt1 ALTER COLUMN c7 DROP NOT NULL;
+ALTER TABLE pt1 ALTER COLUMN c8 TYPE char(10) USING '0'; -- ERROR
+ERROR: "ft2" is not a table
+ALTER TABLE pt1 ALTER COLUMN c8 TYPE char(10);
+ALTER TABLE pt1 ALTER COLUMN c8 SET DATA TYPE text;
+ALTER TABLE pt1 ALTER COLUMN c1 SET STATISTICS 10000;
+ALTER TABLE pt1 ALTER COLUMN c1 SET (n_distinct = 100);
+ALTER TABLE pt1 ALTER COLUMN c8 SET STATISTICS -1;
+ALTER TABLE pt1 ALTER COLUMN c8 SET STORAGE EXTERNAL;
+\d+ pt1
+ Table "public.pt1"
+ Column | Type | Modifiers | Storage | Stats target | Description
+--------+---------+-----------+----------+--------------+-------------
+ c1 | integer | not null | plain | 10000 |
+ c2 | text | | extended | |
+ c3 | date | | plain | |
+ c4 | integer | default 0 | plain | |
+ c5 | integer | | plain | |
+ c6 | integer | not null | plain | |
+ c7 | integer | | plain | |
+ c8 | text | | external | |
+Child tables: ft2
+
+\d+ ft2
+ Foreign table "public.ft2"
+ Column | Type | Modifiers | FDW Options | Storage | Stats target | Description
+--------+---------+-----------+-------------+----------+--------------+-------------
+ c1 | integer | not null | | plain | 10000 |
+ c2 | text | | | extended | |
+ c3 | date | | | plain | |
+ c4 | integer | default 0 | | plain | |
+ c5 | integer | | | plain | |
+ c6 | integer | not null | | plain | |
+ c7 | integer | | | plain | |
+ c8 | text | | | external | |
+Server: s0
+FDW Options: (delimiter ',', quote '"', "be quoted" 'value')
+Inherits: pt1
+Child tables: ct3,
+ ft3
+
+-- drop attributes recursively
+ALTER TABLE pt1 DROP COLUMN c4;
+ALTER TABLE pt1 DROP COLUMN c5;
+ALTER TABLE pt1 DROP COLUMN c6;
+ALTER TABLE pt1 DROP COLUMN c7;
+ALTER TABLE pt1 DROP COLUMN c8;
+\d+ pt1
+ Table "public.pt1"
+ Column | Type | Modifiers | Storage | Stats target | Description
+--------+---------+-----------+----------+--------------+-------------
+ c1 | integer | not null | plain | 10000 |
+ c2 | text | | extended | |
+ c3 | date | | plain | |
+Child tables: ft2
+
+\d+ ft2
+ Foreign table "public.ft2"
+ Column | Type | Modifiers | FDW Options | Storage | Stats target | Description
+--------+---------+-----------+-------------+----------+--------------+-------------
+ c1 | integer | not null | | plain | 10000 |
+ c2 | text | | | extended | |
+ c3 | date | | | plain | |
+Server: s0
+FDW Options: (delimiter ',', quote '"', "be quoted" 'value')
+Inherits: pt1
+Child tables: ct3,
+ ft3
+
+-- add constraints recursively
+ALTER TABLE pt1 ADD CONSTRAINT pt1chk1 CHECK (c1 > 0) NO INHERIT;
+ALTER TABLE pt1 ADD CONSTRAINT pt1chk2 CHECK (c2 <> '');
+-- connoinherit should be true for NO INHERIT constraint
+SELECT relname, conname, contype, conislocal, coninhcount, connoinherit
+ FROM pg_class AS pc JOIN pg_constraint AS pgc ON (conrelid = pc.oid)
+ WHERE pc.relname = 'pt1'
+ ORDER BY 1,2;
+ relname | conname | contype | conislocal | coninhcount | connoinherit
+---------+---------+---------+------------+-------------+--------------
+ pt1 | pt1chk1 | c | t | 0 | t
+ pt1 | pt1chk2 | c | t | 0 | f
+(2 rows)
+
+-- child does not inherit NO INHERIT constraints
+\d+ pt1
+ Table "public.pt1"
+ Column | Type | Modifiers | Storage | Stats target | Description
+--------+---------+-----------+----------+--------------+-------------
+ c1 | integer | not null | plain | 10000 |
+ c2 | text | | extended | |
+ c3 | date | | plain | |
+Check constraints:
+ "pt1chk1" CHECK (c1 > 0) NO INHERIT
+ "pt1chk2" CHECK (c2 <> ''::text)
+Child tables: ft2
+
+\d+ ft2
+ Foreign table "public.ft2"
+ Column | Type | Modifiers | FDW Options | Storage | Stats target | Description
+--------+---------+-----------+-------------+----------+--------------+-------------
+ c1 | integer | not null | | plain | 10000 |
+ c2 | text | | | extended | |
+ c3 | date | | | plain | |
+Check constraints:
+ "pt1chk2" CHECK (c2 <> ''::text)
+Server: s0
+FDW Options: (delimiter ',', quote '"', "be quoted" 'value')
+Inherits: pt1
+Child tables: ct3,
+ ft3
+
+DROP FOREIGN TABLE ft2; -- ERROR
+ERROR: cannot drop foreign table ft2 because other objects depend on it
+DETAIL: table ct3 depends on foreign table ft2
+foreign table ft3 depends on foreign table ft2
+HINT: Use DROP ... CASCADE to drop the dependent objects too.
+DROP FOREIGN TABLE ft2 CASCADE;
+NOTICE: drop cascades to 2 other objects
+DETAIL: drop cascades to table ct3
+drop cascades to foreign table ft3
+CREATE FOREIGN TABLE ft2 (
+ c1 integer NOT NULL,
+ c2 text,
+ c3 date
+) SERVER s0 OPTIONS (delimiter ',', quote '"', "be quoted" 'value');
+-- child must have parent's INHERIT constraints
+ALTER FOREIGN TABLE ft2 INHERIT pt1; -- ERROR
+ERROR: child table is missing constraint "pt1chk2"
+ALTER FOREIGN TABLE ft2 ADD CONSTRAINT pt1chk2 CHECK (c2 <> '');
+ALTER FOREIGN TABLE ft2 INHERIT pt1;
+-- child does not inherit NO INHERIT constraints
+\d+ pt1
+ Table "public.pt1"
+ Column | Type | Modifiers | Storage | Stats target | Description
+--------+---------+-----------+----------+--------------+-------------
+ c1 | integer | not null | plain | 10000 |
+ c2 | text | | extended | |
+ c3 | date | | plain | |
+Check constraints:
+ "pt1chk1" CHECK (c1 > 0) NO INHERIT
+ "pt1chk2" CHECK (c2 <> ''::text)
+Child tables: ft2
+
+\d+ ft2
+ Foreign table "public.ft2"
+ Column | Type | Modifiers | FDW Options | Storage | Stats target | Description
+--------+---------+-----------+-------------+----------+--------------+-------------
+ c1 | integer | not null | | plain | |
+ c2 | text | | | extended | |
+ c3 | date | | | plain | |
+Check constraints:
+ "pt1chk2" CHECK (c2 <> ''::text)
+Server: s0
+FDW Options: (delimiter ',', quote '"', "be quoted" 'value')
+Inherits: pt1
+
+-- drop constraints recursively
+ALTER TABLE pt1 DROP CONSTRAINT pt1chk1 CASCADE;
+ALTER TABLE pt1 DROP CONSTRAINT pt1chk2 CASCADE;
+-- NOT VALID case
+INSERT INTO pt1 VALUES (1, 'pt1'::text, '1994-01-01'::date);
+ALTER TABLE pt1 ADD CONSTRAINT pt1chk3 CHECK (c2 <> '') NOT VALID;
+\d+ pt1
+ Table "public.pt1"
+ Column | Type | Modifiers | Storage | Stats target | Description
+--------+---------+-----------+----------+--------------+-------------
+ c1 | integer | not null | plain | 10000 |
+ c2 | text | | extended | |
+ c3 | date | | plain | |
+Check constraints:
+ "pt1chk3" CHECK (c2 <> ''::text) NOT VALID
+Child tables: ft2
+
+\d+ ft2
+ Foreign table "public.ft2"
+ Column | Type | Modifiers | FDW Options | Storage | Stats target | Description
+--------+---------+-----------+-------------+----------+--------------+-------------
+ c1 | integer | not null | | plain | |
+ c2 | text | | | extended | |
+ c3 | date | | | plain | |
+Check constraints:
+ "pt1chk2" CHECK (c2 <> ''::text)
+ "pt1chk3" CHECK (c2 <> ''::text) NOT VALID
+Server: s0
+FDW Options: (delimiter ',', quote '"', "be quoted" 'value')
+Inherits: pt1
+
+-- VALIDATE CONSTRAINT need do nothing on foreign tables
+ALTER TABLE pt1 VALIDATE CONSTRAINT pt1chk3;
+\d+ pt1
+ Table "public.pt1"
+ Column | Type | Modifiers | Storage | Stats target | Description
+--------+---------+-----------+----------+--------------+-------------
+ c1 | integer | not null | plain | 10000 |
+ c2 | text | | extended | |
+ c3 | date | | plain | |
+Check constraints:
+ "pt1chk3" CHECK (c2 <> ''::text)
+Child tables: ft2
+
+\d+ ft2
+ Foreign table "public.ft2"
+ Column | Type | Modifiers | FDW Options | Storage | Stats target | Description
+--------+---------+-----------+-------------+----------+--------------+-------------
+ c1 | integer | not null | | plain | |
+ c2 | text | | | extended | |
+ c3 | date | | | plain | |
+Check constraints:
+ "pt1chk2" CHECK (c2 <> ''::text)
+ "pt1chk3" CHECK (c2 <> ''::text)
+Server: s0
+FDW Options: (delimiter ',', quote '"', "be quoted" 'value')
+Inherits: pt1
+
+-- OID system column
+ALTER TABLE pt1 SET WITH OIDS;
+\d+ pt1
+ Table "public.pt1"
+ Column | Type | Modifiers | Storage | Stats target | Description
+--------+---------+-----------+----------+--------------+-------------
+ c1 | integer | not null | plain | 10000 |
+ c2 | text | | extended | |
+ c3 | date | | plain | |
+Check constraints:
+ "pt1chk3" CHECK (c2 <> ''::text)
+Child tables: ft2
+Has OIDs: yes
+
+\d+ ft2
+ Foreign table "public.ft2"
+ Column | Type | Modifiers | FDW Options | Storage | Stats target | Description
+--------+---------+-----------+-------------+----------+--------------+-------------
+ c1 | integer | not null | | plain | |
+ c2 | text | | | extended | |
+ c3 | date | | | plain | |
+Check constraints:
+ "pt1chk2" CHECK (c2 <> ''::text)
+ "pt1chk3" CHECK (c2 <> ''::text)
+Server: s0
+FDW Options: (delimiter ',', quote '"', "be quoted" 'value')
+Inherits: pt1
+Has OIDs: yes
+
+ALTER TABLE ft2 SET WITHOUT OIDS; -- ERROR
+ERROR: cannot drop inherited column "oid"
+ALTER TABLE pt1 SET WITHOUT OIDS;
+\d+ pt1
+ Table "public.pt1"
+ Column | Type | Modifiers | Storage | Stats target | Description
+--------+---------+-----------+----------+--------------+-------------
+ c1 | integer | not null | plain | 10000 |
+ c2 | text | | extended | |
+ c3 | date | | plain | |
+Check constraints:
+ "pt1chk3" CHECK (c2 <> ''::text)
+Child tables: ft2
+
+\d+ ft2
+ Foreign table "public.ft2"
+ Column | Type | Modifiers | FDW Options | Storage | Stats target | Description
+--------+---------+-----------+-------------+----------+--------------+-------------
+ c1 | integer | not null | | plain | |
+ c2 | text | | | extended | |
+ c3 | date | | | plain | |
+Check constraints:
+ "pt1chk2" CHECK (c2 <> ''::text)
+ "pt1chk3" CHECK (c2 <> ''::text)
+Server: s0
+FDW Options: (delimiter ',', quote '"', "be quoted" 'value')
+Inherits: pt1
+
+-- changes name of an attribute recursively
+ALTER TABLE pt1 RENAME COLUMN c1 TO f1;
+ALTER TABLE pt1 RENAME COLUMN c2 TO f2;
+ALTER TABLE pt1 RENAME COLUMN c3 TO f3;
+-- changes name of a constraint recursively
+ALTER TABLE pt1 RENAME CONSTRAINT pt1chk3 TO f2_check;
+\d+ pt1
+ Table "public.pt1"
+ Column | Type | Modifiers | Storage | Stats target | Description
+--------+---------+-----------+----------+--------------+-------------
+ f1 | integer | not null | plain | 10000 |
+ f2 | text | | extended | |
+ f3 | date | | plain | |
+Check constraints:
+ "f2_check" CHECK (f2 <> ''::text)
+Child tables: ft2
+
+\d+ ft2
+ Foreign table "public.ft2"
+ Column | Type | Modifiers | FDW Options | Storage | Stats target | Description
+--------+---------+-----------+-------------+----------+--------------+-------------
+ f1 | integer | not null | | plain | |
+ f2 | text | | | extended | |
+ f3 | date | | | plain | |
+Check constraints:
+ "f2_check" CHECK (f2 <> ''::text)
+ "pt1chk2" CHECK (f2 <> ''::text)
+Server: s0
+FDW Options: (delimiter ',', quote '"', "be quoted" 'value')
+Inherits: pt1
+
+-- TRUNCATE doesn't work on foreign tables, either directly or recursively
+TRUNCATE ft2; -- ERROR
+ERROR: "ft2" is not a table
+TRUNCATE pt1; -- ERROR
+ERROR: "ft2" is not a table
+DROP TABLE pt1 CASCADE;
+NOTICE: drop cascades to foreign table ft2
-- IMPORT FOREIGN SCHEMA
IMPORT FOREIGN SCHEMA s1 FROM SERVER s9 INTO public; -- ERROR
ERROR: foreign-data wrapper "foo" has no handler
QUERY PLAN
-------------------------------------------
Update on t1 t1_3
+ Update on t1 t1_3
+ Update on t2 t1
+ Update on t3 t1
-> Subquery Scan on t1
Filter: f_leak(t1.b)
-> LockRows
-> LockRows
-> Seq Scan on t3
Filter: ((a % 2) = 0)
-(16 rows)
+(19 rows)
UPDATE t1 SET b = b || b WHERE f_leak(b);
NOTICE: f_leak => bbb
QUERY PLAN
-------------------------------------------
Delete on t1 t1_3
+ Delete on t1 t1_3
+ Delete on t2 t1
+ Delete on t3 t1
-> Subquery Scan on t1
Filter: f_leak(t1.b)
-> LockRows
-> LockRows
-> Seq Scan on t3
Filter: ((a % 2) = 0)
-(16 rows)
+(19 rows)
DELETE FROM only t1 WHERE f_leak(b) RETURNING oid, *, t1;
NOTICE: f_leak => bbbbbb_updt
QUERY PLAN
------------------------------------------------------------------------------------------------------------------------------------
Update on public.t1 t1_4
+ Update on public.t1 t1_4
+ Update on public.t11 t1
+ Update on public.t12 t1
+ Update on public.t111 t1
-> Subquery Scan on t1
Output: 100, t1.b, t1.c, t1.ctid
Filter: snoop(t1.a)
-> Seq Scan on public.t111 t111_4
Output: t111_4.ctid, t111_4.tableoid, t111_4.a
Filter: (t111_4.a = 3)
-(69 rows)
+(73 rows)
UPDATE v1 SET a=100 WHERE snoop(a) AND leakproof(a) AND a = 3;
SELECT * FROM v1 WHERE a=100; -- Nothing should have been changed to 100
QUERY PLAN
------------------------------------------------------------------------------------------------------------------------------------
Update on public.t1 t1_4
+ Update on public.t1 t1_4
+ Update on public.t11 t1
+ Update on public.t12 t1
+ Update on public.t111 t1
-> Subquery Scan on t1
Output: (t1.a + 1), t1.b, t1.c, t1.ctid
Filter: snoop(t1.a)
-> Seq Scan on public.t111 t111_4
Output: t111_4.ctid, t111_4.tableoid, t111_4.a
Filter: (t111_4.a = 8)
-(69 rows)
+(73 rows)
UPDATE v1 SET a=a+1 WHERE snoop(a) AND leakproof(a) AND a = 8;
NOTICE: snooped value: 8
QUERY PLAN
------------------------------------------------
Delete on public.a
+ Delete on public.a
+ Delete on public.b
+ Delete on public.c
+ Delete on public.d
CTE wcte
-> Insert on public.int8_tbl
Output: int8_tbl.q2
Output: d.ctid, d.aa
-> CTE Scan on wcte
Output: wcte.*, wcte.q2
-(34 rows)
+(38 rows)
-- error cases
-- data-modifying WITH tries to use its own output
ALTER FOREIGN TABLE ft1 ALTER COLUMN c1 SET STATISTICS 10000;
ALTER FOREIGN TABLE ft1 ALTER COLUMN c1 SET (n_distinct = 100);
ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 SET STATISTICS -1;
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 SET STORAGE PLAIN;
\d+ ft1
-- can't change the column type if it's used elsewhere
CREATE TABLE use_ft1_column_type (x ft1);
ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 SET DATA TYPE integer; -- ERROR
DROP TABLE use_ft1_column_type;
ALTER FOREIGN TABLE ft1 ADD PRIMARY KEY (c7); -- ERROR
-ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c9_check CHECK (c9 < 0) NOT VALID; -- ERROR
-ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c9_check CHECK (c9 < 0);
+ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c9_check CHECK (c9 < 0) NOT VALID;
ALTER FOREIGN TABLE ft1 ALTER CONSTRAINT ft1_c9_check DEFERRABLE; -- ERROR
ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c9_check;
ALTER FOREIGN TABLE ft1 DROP CONSTRAINT no_const; -- ERROR
ALTER FOREIGN TABLE ft1 DROP CONSTRAINT IF EXISTS no_const;
-ALTER FOREIGN TABLE ft1 SET WITH OIDS; -- ERROR
+ALTER FOREIGN TABLE ft1 SET WITH OIDS;
ALTER FOREIGN TABLE ft1 OWNER TO regress_test_role;
ALTER FOREIGN TABLE ft1 OPTIONS (DROP delimiter, SET quote '~', ADD escape '@');
ALTER FOREIGN TABLE ft1 DROP COLUMN no_column; -- ERROR
DROP FUNCTION dummy_trigger();
+-- Table inheritance
+CREATE TABLE pt1 (
+ c1 integer NOT NULL,
+ c2 text,
+ c3 date
+);
+CREATE FOREIGN TABLE ft2 () INHERITS (pt1)
+ SERVER s0 OPTIONS (delimiter ',', quote '"', "be quoted" 'value');
+\d+ pt1
+\d+ ft2
+DROP FOREIGN TABLE ft2;
+\d+ pt1
+CREATE FOREIGN TABLE ft2 (
+ c1 integer NOT NULL,
+ c2 text,
+ c3 date
+) SERVER s0 OPTIONS (delimiter ',', quote '"', "be quoted" 'value');
+\d+ ft2
+ALTER FOREIGN TABLE ft2 INHERIT pt1;
+\d+ pt1
+\d+ ft2
+CREATE TABLE ct3() INHERITS(ft2);
+CREATE FOREIGN TABLE ft3 (
+ c1 integer NOT NULL,
+ c2 text,
+ c3 date
+) INHERITS(ft2)
+ SERVER s0;
+\d+ ft2
+\d+ ct3
+\d+ ft3
+
+-- add attributes recursively
+ALTER TABLE pt1 ADD COLUMN c4 integer;
+ALTER TABLE pt1 ADD COLUMN c5 integer DEFAULT 0;
+ALTER TABLE pt1 ADD COLUMN c6 integer;
+ALTER TABLE pt1 ADD COLUMN c7 integer NOT NULL;
+ALTER TABLE pt1 ADD COLUMN c8 integer;
+\d+ pt1
+\d+ ft2
+\d+ ct3
+\d+ ft3
+
+-- alter attributes recursively
+ALTER TABLE pt1 ALTER COLUMN c4 SET DEFAULT 0;
+ALTER TABLE pt1 ALTER COLUMN c5 DROP DEFAULT;
+ALTER TABLE pt1 ALTER COLUMN c6 SET NOT NULL;
+ALTER TABLE pt1 ALTER COLUMN c7 DROP NOT NULL;
+ALTER TABLE pt1 ALTER COLUMN c8 TYPE char(10) USING '0'; -- ERROR
+ALTER TABLE pt1 ALTER COLUMN c8 TYPE char(10);
+ALTER TABLE pt1 ALTER COLUMN c8 SET DATA TYPE text;
+ALTER TABLE pt1 ALTER COLUMN c1 SET STATISTICS 10000;
+ALTER TABLE pt1 ALTER COLUMN c1 SET (n_distinct = 100);
+ALTER TABLE pt1 ALTER COLUMN c8 SET STATISTICS -1;
+ALTER TABLE pt1 ALTER COLUMN c8 SET STORAGE EXTERNAL;
+\d+ pt1
+\d+ ft2
+
+-- drop attributes recursively
+ALTER TABLE pt1 DROP COLUMN c4;
+ALTER TABLE pt1 DROP COLUMN c5;
+ALTER TABLE pt1 DROP COLUMN c6;
+ALTER TABLE pt1 DROP COLUMN c7;
+ALTER TABLE pt1 DROP COLUMN c8;
+\d+ pt1
+\d+ ft2
+
+-- add constraints recursively
+ALTER TABLE pt1 ADD CONSTRAINT pt1chk1 CHECK (c1 > 0) NO INHERIT;
+ALTER TABLE pt1 ADD CONSTRAINT pt1chk2 CHECK (c2 <> '');
+-- connoinherit should be true for NO INHERIT constraint
+SELECT relname, conname, contype, conislocal, coninhcount, connoinherit
+ FROM pg_class AS pc JOIN pg_constraint AS pgc ON (conrelid = pc.oid)
+ WHERE pc.relname = 'pt1'
+ ORDER BY 1,2;
+-- child does not inherit NO INHERIT constraints
+\d+ pt1
+\d+ ft2
+DROP FOREIGN TABLE ft2; -- ERROR
+DROP FOREIGN TABLE ft2 CASCADE;
+CREATE FOREIGN TABLE ft2 (
+ c1 integer NOT NULL,
+ c2 text,
+ c3 date
+) SERVER s0 OPTIONS (delimiter ',', quote '"', "be quoted" 'value');
+-- child must have parent's INHERIT constraints
+ALTER FOREIGN TABLE ft2 INHERIT pt1; -- ERROR
+ALTER FOREIGN TABLE ft2 ADD CONSTRAINT pt1chk2 CHECK (c2 <> '');
+ALTER FOREIGN TABLE ft2 INHERIT pt1;
+-- child does not inherit NO INHERIT constraints
+\d+ pt1
+\d+ ft2
+
+-- drop constraints recursively
+ALTER TABLE pt1 DROP CONSTRAINT pt1chk1 CASCADE;
+ALTER TABLE pt1 DROP CONSTRAINT pt1chk2 CASCADE;
+
+-- NOT VALID case
+INSERT INTO pt1 VALUES (1, 'pt1'::text, '1994-01-01'::date);
+ALTER TABLE pt1 ADD CONSTRAINT pt1chk3 CHECK (c2 <> '') NOT VALID;
+\d+ pt1
+\d+ ft2
+-- VALIDATE CONSTRAINT need do nothing on foreign tables
+ALTER TABLE pt1 VALIDATE CONSTRAINT pt1chk3;
+\d+ pt1
+\d+ ft2
+
+-- OID system column
+ALTER TABLE pt1 SET WITH OIDS;
+\d+ pt1
+\d+ ft2
+ALTER TABLE ft2 SET WITHOUT OIDS; -- ERROR
+ALTER TABLE pt1 SET WITHOUT OIDS;
+\d+ pt1
+\d+ ft2
+
+-- changes name of an attribute recursively
+ALTER TABLE pt1 RENAME COLUMN c1 TO f1;
+ALTER TABLE pt1 RENAME COLUMN c2 TO f2;
+ALTER TABLE pt1 RENAME COLUMN c3 TO f3;
+-- changes name of a constraint recursively
+ALTER TABLE pt1 RENAME CONSTRAINT pt1chk3 TO f2_check;
+\d+ pt1
+\d+ ft2
+
+-- TRUNCATE doesn't work on foreign tables, either directly or recursively
+TRUNCATE ft2; -- ERROR
+TRUNCATE pt1; -- ERROR
+
+DROP TABLE pt1 CASCADE;
+
-- IMPORT FOREIGN SCHEMA
IMPORT FOREIGN SCHEMA s1 FROM SERVER s9 INTO public; -- ERROR
IMPORT FOREIGN SCHEMA s1 LIMIT TO (t1) FROM SERVER s9 INTO public; --ERROR