From: Michael Paquier Date: Wed, 20 Jun 2018 01:42:25 +0000 (+0900) Subject: Clarify use of temporary tables within partition trees X-Git-Tag: REL_11_BETA2~30 X-Git-Url: https://granicus.if.org/sourcecode?a=commitdiff_plain;h=1c7c317cd9d1e5647454deed11b55dae764c83bf;p=postgresql Clarify use of temporary tables within partition trees Since their introduction, partition trees have been a bit lossy regarding temporary relations. Inheritance trees respect the following patterns: 1) a child relation can be temporary if the parent is permanent. 2) a child relation can be temporary if the parent is temporary. 3) a child relation cannot be permanent if the parent is temporary. 4) The use of temporary relations also imply that when both parent and child need to be from the same sessions. Partitions share many similar patterns with inheritance, however the handling of the partition bounds make the situation a bit tricky for case 1) as the partition code bases a lot of its lookup code upon PartitionDesc which does not really look after relpersistence. This causes for example a temporary partition created by session A to be visible by another session B, preventing this session B to create an extra partition which overlaps with the temporary one created by A with a non-intuitive error message. There could be use-cases where mixing permanent partitioned tables with temporary partitions make sense, but that would be a new feature. Partitions respect 2), 3) and 4) already. It is a bit depressing to see those error checks happening in MergeAttributes() whose purpose is different, but that's left as future refactoring work. Back-patch down to 10, which is where partitioning has been introduced, except that default partitions do not apply there. Documentation also includes limitations related to the use of temporary tables with partition trees. Reported-by: David Rowley Author: Amit Langote, Michael Paquier Reviewed-by: Ashutosh Bapat, Amit Langote, Michael Paquier Discussion: https://postgr.es/m/CAKJS1f94Ojk0og9GMkRHGt8wHTW=ijq5KzJKuoBoqWLwSVwGmw@mail.gmail.com --- diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml index 0258391154..50dc25f87f 100644 --- a/doc/src/sgml/ddl.sgml +++ b/doc/src/sgml/ddl.sgml @@ -3353,6 +3353,16 @@ ALTER TABLE measurement ATTACH PARTITION measurement_y2008m02 on individual partitions, not the partitioned table. + + + + Mixing temporary and permanent relations in the same partition tree is + not allowed. Hence, if the partitioned table is permanent, so must be + its partitions and likewise if the partitioned table is temporary. When + using temporary relations, all members of the partition tree have to be + from the same session. + + diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c index 8b848f91a7..7c0cf0d7ee 100644 --- a/src/backend/commands/tablecmds.c +++ b/src/backend/commands/tablecmds.c @@ -1985,6 +1985,19 @@ MergeAttributes(List *schema, List *supers, char relpersistence, (errcode(ERRCODE_WRONG_OBJECT_TYPE), errmsg("inherited relation \"%s\" is not a table or foreign table", parent->relname))); + + /* + * If the parent is permanent, so must be all of its partitions. Note + * that inheritance allows that case. + */ + if (is_partition && + relation->rd_rel->relpersistence != RELPERSISTENCE_TEMP && + relpersistence == RELPERSISTENCE_TEMP) + ereport(ERROR, + (errcode(ERRCODE_WRONG_OBJECT_TYPE), + errmsg("cannot create a temporary relation as partition of permanent relation \"%s\"", + RelationGetRelationName(relation)))); + /* Permanent rels cannot inherit from temporary ones */ if (relpersistence != RELPERSISTENCE_TEMP && relation->rd_rel->relpersistence == RELPERSISTENCE_TEMP) @@ -14135,6 +14148,14 @@ ATExecAttachPartition(List **wqueue, Relation rel, PartitionCmd *cmd) RelationGetRelationName(rel), RelationGetRelationName(attachrel)))); + /* If the parent is permanent, so must be all of its partitions. */ + if (rel->rd_rel->relpersistence != RELPERSISTENCE_TEMP && + attachrel->rd_rel->relpersistence == RELPERSISTENCE_TEMP) + ereport(ERROR, + (errcode(ERRCODE_WRONG_OBJECT_TYPE), + errmsg("cannot attach a temporary relation as partition of permanent relation \"%s\"", + RelationGetRelationName(rel)))); + /* Temp parent cannot have a partition that is itself not a temp */ if (rel->rd_rel->relpersistence == RELPERSISTENCE_TEMP && attachrel->rd_rel->relpersistence != RELPERSISTENCE_TEMP) diff --git a/src/test/regress/expected/alter_table.out b/src/test/regress/expected/alter_table.out index 702bf9fe98..b9fd6d1d1c 100644 --- a/src/test/regress/expected/alter_table.out +++ b/src/test/regress/expected/alter_table.out @@ -3894,3 +3894,16 @@ alter table defpart_attach_test_d add check (a > 1); alter table defpart_attach_test attach partition defpart_attach_test_d default; INFO: partition constraint for table "defpart_attach_test_d" is implied by existing constraints drop table defpart_attach_test; +-- check combinations of temporary and permanent relations when attaching +-- partitions. +create table perm_part_parent (a int) partition by list (a); +create temp table temp_part_parent (a int) partition by list (a); +create table perm_part_child (a int); +create temp table temp_part_child (a int); +alter table temp_part_parent attach partition perm_part_child default; -- error +ERROR: cannot attach a permanent relation as partition of temporary relation "temp_part_parent" +alter table perm_part_parent attach partition temp_part_child default; -- error +ERROR: cannot attach a temporary relation as partition of permanent relation "perm_part_parent" +alter table temp_part_parent attach partition temp_part_child default; -- ok +drop table perm_part_parent cascade; +drop table temp_part_parent cascade; diff --git a/src/test/regress/expected/create_table.out b/src/test/regress/expected/create_table.out index 470fca0cab..672719e5d5 100644 --- a/src/test/regress/expected/create_table.out +++ b/src/test/regress/expected/create_table.out @@ -899,3 +899,13 @@ Partitions: boolspart_f FOR VALUES IN (false), boolspart_t FOR VALUES IN (true) drop table boolspart; +-- partitions mixing temporary and permanent relations +create table perm_parted (a int) partition by list (a); +create temporary table temp_parted (a int) partition by list (a); +create table perm_part partition of temp_parted default; -- error +ERROR: cannot create a permanent relation as partition of temporary relation "temp_parted" +create temp table temp_part partition of perm_parted default; -- error +ERROR: cannot create a temporary relation as partition of permanent relation "perm_parted" +create temp table temp_part partition of temp_parted default; -- ok +drop table perm_parted cascade; +drop table temp_parted cascade; diff --git a/src/test/regress/expected/foreign_data.out b/src/test/regress/expected/foreign_data.out index 339a43ff9e..75365501d4 100644 --- a/src/test/regress/expected/foreign_data.out +++ b/src/test/regress/expected/foreign_data.out @@ -2045,6 +2045,17 @@ TRUNCATE fd_pt2; -- ERROR ERROR: "fd_pt2_1" is not a table DROP FOREIGN TABLE fd_pt2_1; DROP TABLE fd_pt2; +-- foreign table cannot be part of partition tree made of temporary +-- relations. +CREATE TEMP TABLE temp_parted (a int) PARTITION BY LIST (a); +CREATE FOREIGN TABLE foreign_part PARTITION OF temp_parted DEFAULT + SERVER s0; -- ERROR +ERROR: cannot create a permanent relation as partition of temporary relation "temp_parted" +CREATE FOREIGN TABLE foreign_part (a int) SERVER s0; +ALTER TABLE temp_parted ATTACH PARTITION foreign_part DEFAULT; -- ERROR +ERROR: cannot attach a permanent relation as partition of temporary relation "temp_parted" +DROP FOREIGN TABLE foreign_part; +DROP TABLE temp_parted; -- Cleanup DROP SCHEMA foreign_schema CASCADE; DROP ROLE regress_test_role; -- ERROR diff --git a/src/test/regress/expected/partition_prune.out b/src/test/regress/expected/partition_prune.out index 854b553d0a..9059147e17 100644 --- a/src/test/regress/expected/partition_prune.out +++ b/src/test/regress/expected/partition_prune.out @@ -3086,3 +3086,24 @@ NOTICE: drop cascades to 2 other objects \set VERBOSITY default reset enable_partition_pruning; reset constraint_exclusion; +-- Check pruning for a partition tree containing only temporary relations +create temp table pp_temp_parent (a int) partition by list (a); +create temp table pp_temp_part_1 partition of pp_temp_parent for values in (1); +create temp table pp_temp_part_def partition of pp_temp_parent default; +explain (costs off) select * from pp_temp_parent where true; + QUERY PLAN +------------------------------------ + Append + -> Seq Scan on pp_temp_part_1 + -> Seq Scan on pp_temp_part_def +(3 rows) + +explain (costs off) select * from pp_temp_parent where a = 2; + QUERY PLAN +------------------------------------ + Append + -> Seq Scan on pp_temp_part_def + Filter: (a = 2) +(3 rows) + +drop table pp_temp_parent; diff --git a/src/test/regress/sql/alter_table.sql b/src/test/regress/sql/alter_table.sql index d508a69456..3a5b80ea81 100644 --- a/src/test/regress/sql/alter_table.sql +++ b/src/test/regress/sql/alter_table.sql @@ -2573,3 +2573,15 @@ alter table defpart_attach_test_d add check (a > 1); alter table defpart_attach_test attach partition defpart_attach_test_d default; drop table defpart_attach_test; + +-- check combinations of temporary and permanent relations when attaching +-- partitions. +create table perm_part_parent (a int) partition by list (a); +create temp table temp_part_parent (a int) partition by list (a); +create table perm_part_child (a int); +create temp table temp_part_child (a int); +alter table temp_part_parent attach partition perm_part_child default; -- error +alter table perm_part_parent attach partition temp_part_child default; -- error +alter table temp_part_parent attach partition temp_part_child default; -- ok +drop table perm_part_parent cascade; +drop table temp_part_parent cascade; diff --git a/src/test/regress/sql/create_table.sql b/src/test/regress/sql/create_table.sql index 140bf41f76..78944950fe 100644 --- a/src/test/regress/sql/create_table.sql +++ b/src/test/regress/sql/create_table.sql @@ -726,3 +726,12 @@ create table boolspart_t partition of boolspart for values in (true); create table boolspart_f partition of boolspart for values in (false); \d+ boolspart drop table boolspart; + +-- partitions mixing temporary and permanent relations +create table perm_parted (a int) partition by list (a); +create temporary table temp_parted (a int) partition by list (a); +create table perm_part partition of temp_parted default; -- error +create temp table temp_part partition of perm_parted default; -- error +create temp table temp_part partition of temp_parted default; -- ok +drop table perm_parted cascade; +drop table temp_parted cascade; diff --git a/src/test/regress/sql/foreign_data.sql b/src/test/regress/sql/foreign_data.sql index c029b2465d..dab9b62900 100644 --- a/src/test/regress/sql/foreign_data.sql +++ b/src/test/regress/sql/foreign_data.sql @@ -805,6 +805,16 @@ TRUNCATE fd_pt2; -- ERROR DROP FOREIGN TABLE fd_pt2_1; DROP TABLE fd_pt2; +-- foreign table cannot be part of partition tree made of temporary +-- relations. +CREATE TEMP TABLE temp_parted (a int) PARTITION BY LIST (a); +CREATE FOREIGN TABLE foreign_part PARTITION OF temp_parted DEFAULT + SERVER s0; -- ERROR +CREATE FOREIGN TABLE foreign_part (a int) SERVER s0; +ALTER TABLE temp_parted ATTACH PARTITION foreign_part DEFAULT; -- ERROR +DROP FOREIGN TABLE foreign_part; +DROP TABLE temp_parted; + -- Cleanup DROP SCHEMA foreign_schema CASCADE; DROP ROLE regress_test_role; -- ERROR diff --git a/src/test/regress/sql/partition_prune.sql b/src/test/regress/sql/partition_prune.sql index ae361b52f9..11b92bfada 100644 --- a/src/test/regress/sql/partition_prune.sql +++ b/src/test/regress/sql/partition_prune.sql @@ -813,3 +813,11 @@ drop table inh_lp cascade; reset enable_partition_pruning; reset constraint_exclusion; + +-- Check pruning for a partition tree containing only temporary relations +create temp table pp_temp_parent (a int) partition by list (a); +create temp table pp_temp_part_1 partition of pp_temp_parent for values in (1); +create temp table pp_temp_part_def partition of pp_temp_parent default; +explain (costs off) select * from pp_temp_parent where true; +explain (costs off) select * from pp_temp_parent where a = 2; +drop table pp_temp_parent;