diff --git a/contrib/file_fdw/input/file_fdw.source b/contrib/file_fdw/input/file_fdw.source index b608372825eb318081cb0161781303463174c36d..e975bc552e35fb8bbfeb1f24b4cc8429f46eef75 100644 --- a/contrib/file_fdw/input/file_fdw.source +++ b/contrib/file_fdw/input/file_fdw.source @@ -62,7 +62,7 @@ CREATE FOREIGN TABLE tbl () SERVER file_server OPTIONS (format 'csv', null ' CREATE FOREIGN TABLE tbl () SERVER file_server; -- ERROR CREATE FOREIGN TABLE agg_text ( - a int2, + a int2 CHECK (a >= 0), b float4 ) SERVER file_server OPTIONS (format 'text', filename '@abs_srcdir@/data/agg.data', delimiter ' ', null '\N'); @@ -72,11 +72,13 @@ CREATE FOREIGN TABLE agg_csv ( b float4 ) SERVER file_server OPTIONS (format 'csv', filename '@abs_srcdir@/data/agg.csv', header 'true', delimiter ';', quote '@', escape '"', null ''); +ALTER FOREIGN TABLE agg_csv ADD CHECK (a >= 0); CREATE FOREIGN TABLE agg_bad ( a int2, b float4 ) SERVER file_server OPTIONS (format 'csv', filename '@abs_srcdir@/data/agg.bad', header 'true', delimiter ';', quote '@', escape '"', null ''); +ALTER FOREIGN TABLE agg_bad ADD CHECK (a >= 0); -- per-column options tests CREATE FOREIGN TABLE text_csv ( @@ -134,6 +136,18 @@ DELETE FROM agg_csv WHERE a = 100; -- but this should be ignored SELECT * FROM agg_csv FOR UPDATE; +-- constraint exclusion tests +\t on +EXPLAIN (VERBOSE, COSTS FALSE) SELECT * FROM agg_csv WHERE a < 0; +\t off +SELECT * FROM agg_csv WHERE a < 0; +SET constraint_exclusion = 'on'; +\t on +EXPLAIN (VERBOSE, COSTS FALSE) SELECT * FROM agg_csv WHERE a < 0; +\t off +SELECT * FROM agg_csv WHERE a < 0; +RESET constraint_exclusion; + -- privilege tests SET ROLE file_fdw_superuser; SELECT * FROM agg_text ORDER BY a; diff --git a/contrib/file_fdw/output/file_fdw.source b/contrib/file_fdw/output/file_fdw.source index bc183b88744d94340f83dd578e1b829aba5704aa..6808d5b2f8f7750c39435fa9f9ec3b9761415a86 100644 --- a/contrib/file_fdw/output/file_fdw.source +++ b/contrib/file_fdw/output/file_fdw.source @@ -78,7 +78,7 @@ ERROR: COPY null representation cannot use newline or carriage return CREATE FOREIGN TABLE tbl () SERVER file_server; -- ERROR ERROR: filename is required for file_fdw foreign tables CREATE FOREIGN TABLE agg_text ( - a int2, + a int2 CHECK (a >= 0), b float4 ) SERVER file_server OPTIONS (format 'text', filename '@abs_srcdir@/data/agg.data', delimiter ' ', null '\N'); @@ -88,11 +88,13 @@ CREATE FOREIGN TABLE agg_csv ( b float4 ) SERVER file_server OPTIONS (format 'csv', filename '@abs_srcdir@/data/agg.csv', header 'true', delimiter ';', quote '@', escape '"', null ''); +ALTER FOREIGN TABLE agg_csv ADD CHECK (a >= 0); CREATE FOREIGN TABLE agg_bad ( a int2, b float4 ) SERVER file_server OPTIONS (format 'csv', filename '@abs_srcdir@/data/agg.bad', header 'true', delimiter ';', quote '@', escape '"', null ''); +ALTER FOREIGN TABLE agg_bad ADD CHECK (a >= 0); -- per-column options tests CREATE FOREIGN TABLE text_csv ( word1 text OPTIONS (force_not_null 'true'), @@ -219,6 +221,34 @@ SELECT * FROM agg_csv FOR UPDATE; 42 | 324.78 (3 rows) +-- constraint exclusion tests +\t on +EXPLAIN (VERBOSE, COSTS FALSE) SELECT * FROM agg_csv WHERE a < 0; + Foreign Scan on public.agg_csv + Output: a, b + Filter: (agg_csv.a < 0) + Foreign File: @abs_srcdir@/data/agg.csv + +\t off +SELECT * FROM agg_csv WHERE a < 0; + a | b +---+--- +(0 rows) + +SET constraint_exclusion = 'on'; +\t on +EXPLAIN (VERBOSE, COSTS FALSE) SELECT * FROM agg_csv WHERE a < 0; + Result + Output: a, b + One-Time Filter: false + +\t off +SELECT * FROM agg_csv WHERE a < 0; + a | b +---+--- +(0 rows) + +RESET constraint_exclusion; -- privilege tests SET ROLE file_fdw_superuser; SELECT * FROM agg_text ORDER BY a; diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out index a335e56a9dfc6a68f34d9d6d8eab8f2cf91867db..583cce738aaa987bef3bbf6d7ad8b50663741ea3 100644 --- a/contrib/postgres_fdw/expected/postgres_fdw.out +++ b/contrib/postgres_fdw/expected/postgres_fdw.out @@ -2588,6 +2588,91 @@ select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1; 407 | 100 (13 rows) +-- =================================================================== +-- test check constraints +-- =================================================================== +-- Consistent check constraints provide consistent results +ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2positive CHECK (c2 >= 0); +EXPLAIN (VERBOSE, COSTS false) SELECT count(*) FROM ft1 WHERE c2 < 0; + QUERY PLAN +------------------------------------------------------------------- + Aggregate + Output: count(*) + -> Foreign Scan on public.ft1 + Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE ((c2 < 0)) +(4 rows) + +SELECT count(*) FROM ft1 WHERE c2 < 0; + count +------- + 0 +(1 row) + +SET constraint_exclusion = 'on'; +EXPLAIN (VERBOSE, COSTS false) SELECT count(*) FROM ft1 WHERE c2 < 0; + QUERY PLAN +-------------------------------- + Aggregate + Output: count(*) + -> Result + One-Time Filter: false +(4 rows) + +SELECT count(*) FROM ft1 WHERE c2 < 0; + count +------- + 0 +(1 row) + +RESET constraint_exclusion; +-- check constraint is enforced on the remote side, not locally +INSERT INTO ft1(c1, c2) VALUES(1111, -2); -- c2positive +ERROR: new row for relation "T 1" violates check constraint "c2positive" +DETAIL: Failing row contains (1111, -2, null, null, null, null, ft1 , null). +CONTEXT: Remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8) +UPDATE ft1 SET c2 = -c2 WHERE c1 = 1; -- c2positive +ERROR: new row for relation "T 1" violates check constraint "c2positive" +DETAIL: Failing row contains (1, -1, 00001_trig_update, 1970-01-02 08:00:00+00, 1970-01-02 00:00:00, 1, 1 , foo). +CONTEXT: Remote SQL command: UPDATE "S 1"."T 1" SET c2 = $2 WHERE ctid = $1 +ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2positive; +-- But inconsistent check constraints provide inconsistent results +ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2negative CHECK (c2 < 0); +EXPLAIN (VERBOSE, COSTS false) SELECT count(*) FROM ft1 WHERE c2 >= 0; + QUERY PLAN +-------------------------------------------------------------------- + Aggregate + Output: count(*) + -> Foreign Scan on public.ft1 + Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE ((c2 >= 0)) +(4 rows) + +SELECT count(*) FROM ft1 WHERE c2 >= 0; + count +------- + 821 +(1 row) + +SET constraint_exclusion = 'on'; +EXPLAIN (VERBOSE, COSTS false) SELECT count(*) FROM ft1 WHERE c2 >= 0; + QUERY PLAN +-------------------------------- + Aggregate + Output: count(*) + -> Result + One-Time Filter: false +(4 rows) + +SELECT count(*) FROM ft1 WHERE c2 >= 0; + count +------- + 0 +(1 row) + +RESET constraint_exclusion; +-- local check constraint is not actually enforced +INSERT INTO ft1(c1, c2) VALUES(1111, 2); +UPDATE ft1 SET c2 = c2 + 1 WHERE c1 = 1; +ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2negative; -- =================================================================== -- test serial columns (ie, sequence-based defaults) -- =================================================================== diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql index fcfb10d29ea697a6884696a378e9e8e89e8e61de..83e8fa7b045f93481a20f07055d1f6f6224cbdcb 100644 --- a/contrib/postgres_fdw/sql/postgres_fdw.sql +++ b/contrib/postgres_fdw/sql/postgres_fdw.sql @@ -405,6 +405,36 @@ commit; select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1; select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1; +-- =================================================================== +-- test check constraints +-- =================================================================== + +-- Consistent check constraints provide consistent results +ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2positive CHECK (c2 >= 0); +EXPLAIN (VERBOSE, COSTS false) SELECT count(*) FROM ft1 WHERE c2 < 0; +SELECT count(*) FROM ft1 WHERE c2 < 0; +SET constraint_exclusion = 'on'; +EXPLAIN (VERBOSE, COSTS false) SELECT count(*) FROM ft1 WHERE c2 < 0; +SELECT count(*) FROM ft1 WHERE c2 < 0; +RESET constraint_exclusion; +-- check constraint is enforced on the remote side, not locally +INSERT INTO ft1(c1, c2) VALUES(1111, -2); -- c2positive +UPDATE ft1 SET c2 = -c2 WHERE c1 = 1; -- c2positive +ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2positive; + +-- But inconsistent check constraints provide inconsistent results +ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2negative CHECK (c2 < 0); +EXPLAIN (VERBOSE, COSTS false) SELECT count(*) FROM ft1 WHERE c2 >= 0; +SELECT count(*) FROM ft1 WHERE c2 >= 0; +SET constraint_exclusion = 'on'; +EXPLAIN (VERBOSE, COSTS false) SELECT count(*) FROM ft1 WHERE c2 >= 0; +SELECT count(*) FROM ft1 WHERE c2 >= 0; +RESET constraint_exclusion; +-- local check constraint is not actually enforced +INSERT INTO ft1(c1, c2) VALUES(1111, 2); +UPDATE ft1 SET c2 = c2 + 1 WHERE c1 = 1; +ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2negative; + -- =================================================================== -- test serial columns (ie, sequence-based defaults) -- =================================================================== diff --git a/doc/src/sgml/ref/alter_foreign_table.sgml b/doc/src/sgml/ref/alter_foreign_table.sgml index 9d9c439315f3912ca38a0e0aa30effe2458ec504..ff48ab888299ff258e49d0323a54f561993e2c9e 100644 --- a/doc/src/sgml/ref/alter_foreign_table.sgml +++ b/doc/src/sgml/ref/alter_foreign_table.sgml @@ -42,6 +42,8 @@ ALTER FOREIGN TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceab 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> OPTIONS ( [ ADD | SET | DROP ] <replaceable class="PARAMETER">option</replaceable> ['<replaceable class="PARAMETER">value</replaceable>'] [, ... ]) + ADD <replaceable class="PARAMETER">table_constraint</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> @@ -87,16 +89,6 @@ ALTER FOREIGN TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceab </listitem> </varlistentry> - <varlistentry> - <term><literal>IF EXISTS</literal></term> - <listitem> - <para> - Do not throw an error if the foreign table does not exist. A notice is - issued in this case. - </para> - </listitem> - </varlistentry> - <varlistentry> <term><literal>SET DATA TYPE</literal></term> <listitem> @@ -153,41 +145,54 @@ ALTER FOREIGN TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceab </varlistentry> <varlistentry> - <term><literal>DISABLE</literal>/<literal>ENABLE [ REPLICA | ALWAYS ] TRIGGER</literal></term> + <term><literal>ADD <replaceable class="PARAMETER">table_constraint</replaceable></literal></term> <listitem> <para> - These forms configure the firing of trigger(s) belonging to the foreign - table. See the similar form of <xref linkend="sql-altertable"> for more - details. + This form adds a new constraint to a foreign table, using the same + syntax as <xref linkend="SQL-CREATEFOREIGNTABLE">. + Currently only <literal>CHECK</> constraints are supported. + </para> + + <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. </para> </listitem> </varlistentry> <varlistentry> - <term><literal>OWNER</literal></term> + <term><literal>DROP CONSTRAINT [ IF EXISTS ]</literal></term> <listitem> <para> - This form changes the owner of the foreign table to the - specified user. + This form drops the specified constraint on a foreign table. + If <literal>IF EXISTS</literal> is specified and the constraint + does not exist, no error is thrown. + In this case a notice is issued instead. </para> </listitem> </varlistentry> <varlistentry> - <term><literal>RENAME</literal></term> + <term><literal>DISABLE</literal>/<literal>ENABLE [ REPLICA | ALWAYS ] TRIGGER</literal></term> <listitem> <para> - The <literal>RENAME</literal> forms change the name of a foreign table - or the name of an individual column in a foreign table. + These forms configure the firing of trigger(s) belonging to the foreign + table. See the similar form of <xref linkend="sql-altertable"> for more + details. </para> </listitem> </varlistentry> <varlistentry> - <term><literal>SET SCHEMA</literal></term> + <term><literal>OWNER</literal></term> <listitem> <para> - This form moves the foreign table into another schema. + This form changes the owner of the foreign table to the + specified user. </para> </listitem> </varlistentry> @@ -207,6 +212,25 @@ ALTER FOREIGN TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceab </listitem> </varlistentry> + <varlistentry> + <term><literal>RENAME</literal></term> + <listitem> + <para> + The <literal>RENAME</literal> forms change the name of a foreign table + or the name of an individual column in a foreign table. + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><literal>SET SCHEMA</literal></term> + <listitem> + <para> + This form moves the foreign table into another schema. + </para> + </listitem> + </varlistentry> + </variablelist> </para> @@ -218,6 +242,12 @@ ALTER FOREIGN TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceab columns in a single command. </para> + <para> + If the command is written as <literal>ALTER FOREIGN TABLE IF EXISTS ...</> + and the foreign table does not exist, no error is thrown. A notice is + issued in this case. + </para> + <para> You must own the table to use <command>ALTER FOREIGN TABLE</>. To change the schema of a foreign table, you must also have @@ -284,12 +314,30 @@ ALTER FOREIGN TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceab </listitem> </varlistentry> + <varlistentry> + <term><replaceable class="PARAMETER">table_constraint</replaceable></term> + <listitem> + <para> + New table constraint for the foreign table. + </para> + </listitem> + </varlistentry> + + <varlistentry> + <term><replaceable class="PARAMETER">constraint_name</replaceable></term> + <listitem> + <para> + Name of an existing constraint to drop. + </para> + </listitem> + </varlistentry> + <varlistentry> <term><literal>CASCADE</literal></term> <listitem> <para> Automatically drop objects that depend on the dropped column - (for example, views referencing the column). + or constraint (for example, views referencing the column). </para> </listitem> </varlistentry> @@ -298,7 +346,7 @@ ALTER FOREIGN TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceab <term><literal>RESTRICT</literal></term> <listitem> <para> - Refuse to drop the column if there are any dependent + Refuse to drop the column or constraint if there are any dependent objects. This is the default behavior. </para> </listitem> @@ -365,10 +413,10 @@ ALTER FOREIGN TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceab <para> Consistency with the foreign server is not checked when a column is added or removed with <literal>ADD COLUMN</literal> or - <literal>DROP COLUMN</literal>, a <literal>NOT NULL</> constraint is - added, or a column type is changed with <literal>SET DATA TYPE</>. It is - the user's responsibility to ensure that the table definition matches the - remote side. + <literal>DROP COLUMN</literal>, a <literal>NOT NULL</> + or <literal>CHECK</> constraint is added, or a column type is changed + with <literal>SET DATA TYPE</>. It is the user's responsibility to ensure + that the table definition matches the remote side. </para> <para> @@ -413,4 +461,13 @@ ALTER FOREIGN TABLE myschema.distributors OPTIONS (ADD opt1 'value', SET opt2, ' extension of SQL, which disallows zero-column foreign tables. </para> </refsect1> + + <refsect1> + <title>See Also</title> + + <simplelist type="inline"> + <member><xref linkend="sql-createforeigntable"></member> + <member><xref linkend="sql-dropforeigntable"></member> + </simplelist> + </refsect1> </refentry> diff --git a/doc/src/sgml/ref/create_foreign_table.sgml b/doc/src/sgml/ref/create_foreign_table.sgml index 46a20eff14f8f25220a50fa23f1e311fe40f6a65..a24aa6e6d1dc7da0e8ff758c55e7cd5735217f76 100644 --- a/doc/src/sgml/ref/create_foreign_table.sgml +++ b/doc/src/sgml/ref/create_foreign_table.sgml @@ -19,7 +19,8 @@ <refsynopsisdiv> <synopsis> CREATE FOREIGN TABLE [ IF NOT EXISTS ] <replaceable class="PARAMETER">table_name</replaceable> ( [ - <replaceable class="PARAMETER">column_name</replaceable> <replaceable class="PARAMETER">data_type</replaceable> [ OPTIONS ( <replaceable class="PARAMETER">option</replaceable> '<replaceable class="PARAMETER">value</replaceable>' [, ... ] ) ] [ COLLATE <replaceable>collation</replaceable> ] [ <replaceable class="PARAMETER">column_constraint</replaceable> [ ... ] ] + { <replaceable class="PARAMETER">column_name</replaceable> <replaceable class="PARAMETER">data_type</replaceable> [ OPTIONS ( <replaceable class="PARAMETER">option</replaceable> '<replaceable class="PARAMETER">value</replaceable>' [, ... ] ) ] [ COLLATE <replaceable>collation</replaceable> ] [ <replaceable class="PARAMETER">column_constraint</replaceable> [ ... ] ] + | <replaceable>table_constraint</replaceable> } [, ... ] ] ) SERVER <replaceable class="parameter">server_name</replaceable> @@ -30,7 +31,13 @@ CREATE FOREIGN TABLE [ IF NOT EXISTS ] <replaceable class="PARAMETER">table_name [ CONSTRAINT <replaceable class="PARAMETER">constraint_name</replaceable> ] { NOT NULL | NULL | + CHECK ( <replaceable class="PARAMETER">expression</replaceable> ) | DEFAULT <replaceable>default_expr</replaceable> } + +<phrase>and <replaceable class="PARAMETER">table_constraint</replaceable> is:</phrase> + +[ CONSTRAINT <replaceable class="PARAMETER">constraint_name</replaceable> ] +CHECK ( <replaceable class="PARAMETER">expression</replaceable> ) </synopsis> </refsynopsisdiv> @@ -137,6 +144,28 @@ CREATE FOREIGN TABLE [ IF NOT EXISTS ] <replaceable class="PARAMETER">table_name </listitem> </varlistentry> + <varlistentry> + <term><literal>CHECK ( <replaceable class="PARAMETER">expression</replaceable> )</literal></term> + <listitem> + <para> + The <literal>CHECK</> clause specifies an expression producing a + Boolean result which each row in the foreign table is expected + to satisfy; that is, the expression should produce TRUE or UNKNOWN, + never FALSE, for all rows in the foreign table. + A check constraint specified as a column constraint should + reference that column's value only, while an expression + appearing in a table constraint can reference multiple columns. + </para> + + <para> + Currently, <literal>CHECK</literal> expressions cannot contain + subqueries nor refer to variables other than columns of the + current row. The system column <literal>tableoid</literal> + may be referenced, but not any other system column. + </para> + </listitem> + </varlistentry> + <varlistentry> <term><literal>DEFAULT <replaceable>default_expr</replaceable></literal></term> @@ -187,6 +216,40 @@ CREATE FOREIGN TABLE [ IF NOT EXISTS ] <replaceable class="PARAMETER">table_name </refsect1> + <refsect1> + <title>Notes</title> + + <para> + Constraints on foreign tables (such as <literal>CHECK</> + or <literal>NOT NULL</> clauses) are not enforced by the + core <productname>PostgreSQL</> system, and most foreign data wrappers + do not attempt to enforce them either; that is, the constraint is + simply assumed to hold true. There would be little point in such + enforcement since it would only apply to rows inserted or updated via + the foreign table, and not to rows modified by other means, such as + directly on the remote server. Instead, a constraint attached to a + foreign table should represent a constraint that is being enforced by + the remote server. + </para> + + <para> + Some special-purpose foreign data wrappers might be the only access + mechanism for the data they access, and in that case it might be + appropriate for the foreign data wrapper itself to perform constraint + enforcement. But you should not assume that a wrapper does that + unless its documentation says so. + </para> + + <para> + Although <productname>PostgreSQL</> does not attempt to enforce + constraints on foreign tables, it does assume that they are correct + for purposes of query optimization. If there are rows visible in the + foreign table that do not satisfy a declared constraint, queries on + the table might produce incorrect answers. It is the user's + responsibility to ensure that the constraint definition matches + reality. + </para> + </refsect1> <refsect1 id="SQL-CREATEFOREIGNTABLE-examples"> <title>Examples</title> diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c index e523ee923a4ea401d73dff6ac56e5d9b4d2453e2..e360482e1dea94a5bc1ca741fdcc95bb60124912 100644 --- a/src/backend/catalog/heap.c +++ b/src/backend/catalog/heap.c @@ -1091,7 +1091,7 @@ heap_create_with_catalog(const char *relname, */ if (!OidIsValid(relid)) { - /* Use binary-upgrade override for pg_class.oid/relfilenode? */ + /* Use binary-upgrade override for pg_class.oid/relfilenode? */ if (IsBinaryUpgrade && (relkind == RELKIND_RELATION || relkind == RELKIND_SEQUENCE || relkind == RELKIND_VIEW || relkind == RELKIND_MATVIEW || @@ -2244,6 +2244,13 @@ AddRelationNewConstraints(Relation rel, 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. */ diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c index 1e737a01c9f0719fdb514c0b625ee859dfe7fa78..81c5ab27c966585b9a7a6a611f5dcc4ab6bf3ad5 100644 --- a/src/backend/commands/tablecmds.c +++ b/src/backend/commands/tablecmds.c @@ -479,10 +479,6 @@ DefineRelation(CreateStmt *stmt, char relkind, Oid ownerId) ereport(ERROR, (errcode(ERRCODE_INVALID_TABLE_DEFINITION), errmsg("ON COMMIT can only be used on temporary tables"))); - if (stmt->constraints != NIL && relkind == RELKIND_FOREIGN_TABLE) - ereport(ERROR, - (errcode(ERRCODE_WRONG_OBJECT_TYPE), - errmsg("constraints are not supported on foreign tables"))); /* * Look up the namespace in which we are supposed to create the relation, @@ -3154,7 +3150,7 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd, pass = AT_PASS_ADD_INDEX; break; case AT_AddConstraint: /* ADD 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) @@ -3168,7 +3164,7 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd, pass = AT_PASS_ADD_CONSTR; break; case AT_DropConstraint: /* DROP 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) diff --git a/src/backend/parser/parse_utilcmd.c b/src/backend/parser/parse_utilcmd.c index 7c1939f9c45cc6febceb0a9fee9d5b55ceb06df1..b9fbb5b6efdf53b3499153a0fca83b22835df4a4 100644 --- a/src/backend/parser/parse_utilcmd.c +++ b/src/backend/parser/parse_utilcmd.c @@ -515,21 +515,23 @@ transformColumnDefinition(CreateStmtContext *cxt, ColumnDef *column) break; case CONSTR_CHECK: + cxt->ckconstraints = lappend(cxt->ckconstraints, constraint); + break; + + case CONSTR_PRIMARY: if (cxt->isforeign) ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), - errmsg("constraints are not supported on foreign tables"), + errmsg("primary key constraints are not supported on foreign tables"), parser_errposition(cxt->pstate, constraint->location))); - cxt->ckconstraints = lappend(cxt->ckconstraints, constraint); - break; + /* FALL THRU */ - case CONSTR_PRIMARY: case CONSTR_UNIQUE: if (cxt->isforeign) ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), - errmsg("constraints are not supported on foreign tables"), + errmsg("unique constraints are not supported on foreign tables"), parser_errposition(cxt->pstate, constraint->location))); if (constraint->keys == NIL) @@ -546,7 +548,7 @@ transformColumnDefinition(CreateStmtContext *cxt, ColumnDef *column) if (cxt->isforeign) ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), - errmsg("constraints are not supported on foreign tables"), + errmsg("foreign key constraints are not supported on foreign tables"), parser_errposition(cxt->pstate, constraint->location))); @@ -605,18 +607,35 @@ transformColumnDefinition(CreateStmtContext *cxt, ColumnDef *column) static void transformTableConstraint(CreateStmtContext *cxt, Constraint *constraint) { - if (cxt->isforeign) - ereport(ERROR, - (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), - errmsg("constraints are not supported on foreign tables"), - parser_errposition(cxt->pstate, - constraint->location))); - switch (constraint->contype) { case CONSTR_PRIMARY: + if (cxt->isforeign) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("primary key constraints are not supported on foreign tables"), + parser_errposition(cxt->pstate, + constraint->location))); + cxt->ixconstraints = lappend(cxt->ixconstraints, constraint); + break; + case CONSTR_UNIQUE: + if (cxt->isforeign) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("unique constraints are not supported on foreign tables"), + parser_errposition(cxt->pstate, + constraint->location))); + cxt->ixconstraints = lappend(cxt->ixconstraints, constraint); + break; + case CONSTR_EXCLUSION: + if (cxt->isforeign) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("exclusion constraints are not supported on foreign tables"), + parser_errposition(cxt->pstate, + constraint->location))); cxt->ixconstraints = lappend(cxt->ixconstraints, constraint); break; @@ -625,6 +644,12 @@ transformTableConstraint(CreateStmtContext *cxt, Constraint *constraint) break; case CONSTR_FOREIGN: + if (cxt->isforeign) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("foreign key constraints are not supported on foreign tables"), + parser_errposition(cxt->pstate, + constraint->location))); cxt->fkconstraints = lappend(cxt->fkconstraints, constraint); break; diff --git a/src/test/regress/expected/foreign_data.out b/src/test/regress/expected/foreign_data.out index e4dedb0c3ba2ca091da60a105d00f8185eeb27c3..9bca4402f6edfe54c9ef3b7ab4341bad8d7ea2aa 100644 --- a/src/test/regress/expected/foreign_data.out +++ b/src/test/regress/expected/foreign_data.out @@ -669,9 +669,37 @@ ERROR: syntax error at or near "WITH OIDS" LINE 1: CREATE FOREIGN TABLE ft1 () SERVER s0 WITH OIDS; ^ CREATE FOREIGN TABLE ft1 ( - c1 integer OPTIONS ("param 1" 'val1') NOT NULL, + c1 integer OPTIONS ("param 1" 'val1') PRIMARY KEY, + c2 text OPTIONS (param2 'val2', param3 'val3'), + c3 date +) SERVER s0 OPTIONS (delimiter ',', quote '"', "be quoted" 'value'); -- ERROR +ERROR: primary key constraints are not supported on foreign tables +LINE 2: c1 integer OPTIONS ("param 1" 'val1') PRIMARY KEY, + ^ +CREATE TABLE ref_table (id integer PRIMARY KEY); +CREATE FOREIGN TABLE ft1 ( + c1 integer OPTIONS ("param 1" 'val1') REFERENCES ref_table (id), c2 text OPTIONS (param2 'val2', param3 'val3'), c3 date +) SERVER s0 OPTIONS (delimiter ',', quote '"', "be quoted" 'value'); -- ERROR +ERROR: foreign key constraints are not supported on foreign tables +LINE 2: c1 integer OPTIONS ("param 1" 'val1') REFERENCES ref_table ... + ^ +DROP TABLE ref_table; +CREATE FOREIGN TABLE ft1 ( + c1 integer OPTIONS ("param 1" 'val1') NOT NULL, + c2 text OPTIONS (param2 'val2', param3 'val3'), + c3 date, + UNIQUE (c3) +) SERVER s0 OPTIONS (delimiter ',', quote '"', "be quoted" 'value'); -- ERROR +ERROR: unique constraints are not supported on foreign tables +LINE 5: UNIQUE (c3) + ^ +CREATE FOREIGN TABLE ft1 ( + c1 integer OPTIONS ("param 1" 'val1') NOT NULL, + c2 text OPTIONS (param2 'val2', param3 'val3') CHECK (c2 <> ''), + c3 date, + CHECK (c3 BETWEEN '1994-01-01'::date AND '1994-01-31'::date) ) SERVER s0 OPTIONS (delimiter ',', quote '"', "be quoted" 'value'); COMMENT ON FOREIGN TABLE ft1 IS 'ft1'; COMMENT ON COLUMN ft1.c1 IS 'ft1.c1'; @@ -682,6 +710,9 @@ COMMENT ON COLUMN ft1.c1 IS 'ft1.c1'; c1 | integer | not null | ("param 1" 'val1') | plain | | ft1.c1 c2 | text | | (param2 'val2', param3 'val3') | extended | | c3 | date | | | plain | | +Check constraints: + "ft1_c2_check" CHECK (c2 <> ''::text) + "ft1_c3_check" CHECK (c3 >= '01-01-1994'::date AND c3 <= '01-31-1994'::date) Server: s0 FDW Options: (delimiter ',', quote '"', "be quoted" 'value') @@ -740,6 +771,9 @@ ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 SET STATISTICS -1; c8 | text | | (p2 'V2') | extended | | c9 | integer | | | plain | | c10 | integer | | (p1 'v1') | plain | | +Check constraints: + "ft1_c2_check" CHECK (c2 <> ''::text) + "ft1_c3_check" CHECK (c3 >= '01-01-1994'::date AND c3 <= '01-31-1994'::date) Server: s0 FDW Options: (delimiter ',', quote '"', "be quoted" 'value') @@ -748,16 +782,20 @@ CREATE TABLE use_ft1_column_type (x ft1); ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 SET DATA TYPE integer; -- ERROR ERROR: cannot alter foreign table "ft1" because column "use_ft1_column_type.x" uses its row type DROP TABLE use_ft1_column_type; -ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c9_check CHECK (c9 < 0); -- ERROR -ERROR: constraints are not supported on foreign tables -LINE 1: ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c9_check CHECK (c... +ALTER FOREIGN TABLE ft1 ADD PRIMARY KEY (c7); -- ERROR +ERROR: primary key constraints are not supported on foreign tables +LINE 1: ALTER FOREIGN TABLE ft1 ADD PRIMARY KEY (c7); ^ -ALTER FOREIGN TABLE ft1 DROP CONSTRAINT no_const; -- ERROR +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 ALTER CONSTRAINT ft1_c9_check DEFERRABLE; -- ERROR ERROR: "ft1" is not a table +ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c9_check; +ALTER FOREIGN TABLE ft1 DROP CONSTRAINT no_const; -- ERROR +ERROR: constraint "no_const" of relation "ft1" does not exist ALTER FOREIGN TABLE ft1 DROP CONSTRAINT IF EXISTS no_const; -ERROR: "ft1" is not a table -ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c1_check; -ERROR: "ft1" is not a table +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 OWNER TO regress_test_role; @@ -785,6 +823,9 @@ ALTER FOREIGN TABLE foreign_schema.ft1 RENAME TO foreign_table_1; c7 | integer | | (p1 'v1', p2 'v2') c8 | text | | (p2 'V2') c10 | integer | | (p1 'v1') +Check constraints: + "ft1_c2_check" CHECK (c2 <> ''::text) + "ft1_c3_check" CHECK (c3 >= '01-01-1994'::date AND c3 <= '01-31-1994'::date) Server: s0 FDW Options: (quote '~', "be quoted" 'value', escape '@') diff --git a/src/test/regress/sql/foreign_data.sql b/src/test/regress/sql/foreign_data.sql index de9dbc8f386c3f55ff37c19be54dd7586a1d7cd2..b4b999d444e200c5567d445035cf38ac31eaa004 100644 --- a/src/test/regress/sql/foreign_data.sql +++ b/src/test/regress/sql/foreign_data.sql @@ -269,9 +269,28 @@ CREATE FOREIGN TABLE ft1 (); -- ERROR CREATE FOREIGN TABLE ft1 () SERVER no_server; -- ERROR CREATE FOREIGN TABLE ft1 () SERVER s0 WITH OIDS; -- ERROR CREATE FOREIGN TABLE ft1 ( - c1 integer OPTIONS ("param 1" 'val1') NOT NULL, + c1 integer OPTIONS ("param 1" 'val1') PRIMARY KEY, c2 text OPTIONS (param2 'val2', param3 'val3'), c3 date +) SERVER s0 OPTIONS (delimiter ',', quote '"', "be quoted" 'value'); -- ERROR +CREATE TABLE ref_table (id integer PRIMARY KEY); +CREATE FOREIGN TABLE ft1 ( + c1 integer OPTIONS ("param 1" 'val1') REFERENCES ref_table (id), + c2 text OPTIONS (param2 'val2', param3 'val3'), + c3 date +) SERVER s0 OPTIONS (delimiter ',', quote '"', "be quoted" 'value'); -- ERROR +DROP TABLE ref_table; +CREATE FOREIGN TABLE ft1 ( + c1 integer OPTIONS ("param 1" 'val1') NOT NULL, + c2 text OPTIONS (param2 'val2', param3 'val3'), + c3 date, + UNIQUE (c3) +) SERVER s0 OPTIONS (delimiter ',', quote '"', "be quoted" 'value'); -- ERROR +CREATE FOREIGN TABLE ft1 ( + c1 integer OPTIONS ("param 1" 'val1') NOT NULL, + c2 text OPTIONS (param2 'val2', param3 'val3') CHECK (c2 <> ''), + c3 date, + CHECK (c3 BETWEEN '1994-01-01'::date AND '1994-01-31'::date) ) SERVER s0 OPTIONS (delimiter ',', quote '"', "be quoted" 'value'); COMMENT ON FOREIGN TABLE ft1 IS 'ft1'; COMMENT ON COLUMN ft1.c1 IS 'ft1.c1'; @@ -314,10 +333,13 @@ ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 SET STATISTICS -1; 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 CONSTRAINT ft1_c9_check CHECK (c9 < 0); -- ERROR +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 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 DROP CONSTRAINT ft1_c1_check; ALTER FOREIGN TABLE ft1 SET WITH OIDS; -- ERROR ALTER FOREIGN TABLE ft1 OWNER TO regress_test_role; ALTER FOREIGN TABLE ft1 OPTIONS (DROP delimiter, SET quote '~', ADD escape '@');