Commit 6f6b99d1 authored by Robert Haas's avatar Robert Haas

Allow a partitioned table to have a default partition.

Any tuples that don't route to any other partition will route to the
default partition.

Jeevan Ladhe, Beena Emerson, Ashutosh Bapat, Rahila Syed, and Robert
Haas, with review and testing at various stages by (at least) Rushabh
Lathia, Keith Fiske, Amit Langote, Amul Sul, Rajkumar Raghuanshi, Sven
Kunze, Kyotaro Horiguchi, Thom Brown, Rafia Sabih, and Dilip Kumar.

Discussion: http://postgr.es/m/CAH2L28tbN4SYyhS7YV1YBWcitkqbhSWfQCy0G=apRcC_PEO-bg@mail.gmail.com
Discussion: http://postgr.es/m/CAOG9ApEYj34fWMcvBMBQ-YtqR9fTdXhdN82QEKG0SVZ6zeL1xg@mail.gmail.com
parent 2cf15ec8
......@@ -4738,6 +4738,17 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</>:<replaceable>&lt;salt&gt;<
<entry>The number of columns in partition key</entry>
</row>
<row>
<entry><structfield>partdefid</structfield></entry>
<entry><type>oid</type></entry>
<entry><literal><link linkend="catalog-pg-class"><structname>pg_class</structname></link>.oid</literal></entry>
<entry>
The OID of the <structname>pg_class</> entry for the default partition
of this partitioned table, or zero if this partitioned table does not
have a default partition.
</entry>
</row>
<row>
<entry><structfield>partattrs</structfield></entry>
<entry><type>int2vector</type></entry>
......
......@@ -34,7 +34,7 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable>
ALTER TABLE ALL IN TABLESPACE <replaceable class="PARAMETER">name</replaceable> [ OWNED BY <replaceable class="PARAMETER">role_name</replaceable> [, ... ] ]
SET TABLESPACE <replaceable class="PARAMETER">new_tablespace</replaceable> [ NOWAIT ]
ALTER TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable>
ATTACH PARTITION <replaceable class="PARAMETER">partition_name</replaceable> FOR VALUES <replaceable class="PARAMETER">partition_bound_spec</replaceable>
ATTACH PARTITION <replaceable class="PARAMETER">partition_name</replaceable> { FOR VALUES <replaceable class="PARAMETER">partition_bound_spec</replaceable> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable>
DETACH PARTITION <replaceable class="PARAMETER">partition_name</replaceable>
......@@ -765,11 +765,18 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable>
</varlistentry>
<varlistentry>
<term><literal>ATTACH PARTITION <replaceable class="PARAMETER">partition_name</replaceable> FOR VALUES <replaceable class="PARAMETER">partition_bound_spec</replaceable></literal></term>
<term><literal>ATTACH PARTITION <replaceable class="PARAMETER">partition_name</replaceable> { FOR VALUES <replaceable class="PARAMETER">partition_bound_spec</replaceable> | DEFAULT }</literal></term>
<listitem>
<para>
This form attaches an existing table (which might itself be partitioned)
as a partition of the target table using the same syntax for
as a partition of the target table. The table can be attached
as a partition for specific values using <literal>FOR VALUES
</literal> or as a default partition by using <literal>DEFAULT
</literal>.
</para>
<para>
A partition using <literal>FOR VALUES</literal> uses same syntax for
<replaceable class="PARAMETER">partition_bound_spec</replaceable> as
<xref linkend="sql-createtable">. The partition bound specification
must correspond to the partitioning strategy and partition key of the
......@@ -806,6 +813,17 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable>
(See the discussion in <xref linkend="SQL-CREATEFOREIGNTABLE"> about
constraints on the foreign table.)
</para>
<para>
When a table has a default partition, defining a new partition changes
the partition constraint for the default partition. The default
partition can't contain any rows that would need to be moved to the new
partition, and will be scanned to verify that none are present. This
scan, like the scan of the new partition, can be avoided if an
appropriate <literal>CHECK</literal> constraint is present. Also like
the scan of the new partition, it is always skipped when the default
partition is a foreign table.
</para>
</listitem>
</varlistentry>
......@@ -1395,6 +1413,13 @@ ALTER TABLE cities
ATTACH PARTITION cities_ab FOR VALUES IN ('a', 'b');
</programlisting></para>
<para>
Attach a default partition to a partitioned table:
<programlisting>
ALTER TABLE cities
ATTACH PARTITION cities_partdef DEFAULT;
</programlisting></para>
<para>
Detach a partition from partitioned table:
<programlisting>
......
......@@ -49,7 +49,7 @@ CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXI
{ <replaceable class="PARAMETER">column_name</replaceable> [ WITH OPTIONS ] [ <replaceable class="PARAMETER">column_constraint</replaceable> [ ... ] ]
| <replaceable>table_constraint</replaceable> }
[, ... ]
) ] FOR VALUES <replaceable class="PARAMETER">partition_bound_spec</replaceable>
) ] { FOR VALUES <replaceable class="PARAMETER">partition_bound_spec</replaceable> | DEFAULT }
[ PARTITION BY { RANGE | LIST } ( { <replaceable class="parameter">column_name</replaceable> | ( <replaceable class="parameter">expression</replaceable> ) } [ COLLATE <replaceable class="parameter">collation</replaceable> ] [ <replaceable class="parameter">opclass</replaceable> ] [, ... ] ) ]
[ WITH ( <replaceable class="PARAMETER">storage_parameter</replaceable> [= <replaceable class="PARAMETER">value</replaceable>] [, ... ] ) | WITH OIDS | WITHOUT OIDS ]
[ ON COMMIT { PRESERVE ROWS | DELETE ROWS | DROP } ]
......@@ -250,11 +250,13 @@ FROM ( { <replaceable class="PARAMETER">numeric_literal</replaceable> | <replace
</varlistentry>
<varlistentry id="SQL-CREATETABLE-PARTITION">
<term><literal>PARTITION OF <replaceable class="PARAMETER">parent_table</replaceable> FOR VALUES <replaceable class="PARAMETER">partition_bound_spec</replaceable></literal></term>
<term><literal>PARTITION OF <replaceable class="PARAMETER">parent_table</replaceable> { FOR VALUES <replaceable class="PARAMETER">partition_bound_spec</replaceable> | DEFAULT }</literal></term>
<listitem>
<para>
Creates the table as a <firstterm>partition</firstterm> of the specified
parent table.
parent table. The table can be created either as a partition for specific
values using <literal>FOR VALUES</literal> or as a default partition
using <literal>DEFAULT</literal>.
</para>
<para>
......@@ -342,6 +344,26 @@ FROM ( { <replaceable class="PARAMETER">numeric_literal</replaceable> | <replace
allows precisely one value to be stored &mdash; "infinity".
</para>
<para>
If <literal>DEFAULT</literal> is specified, the table will be
created as a default partition of the parent table. The parent can
either be a list or range partitioned table. A partition key value
not fitting into any other partition of the given parent will be
routed to the default partition. There can be only one default
partition for a given parent table.
</para>
<para>
When a table has an existing <literal>DEFAULT</literal> partition and
a new partition is added to it, the existing default partition must
be scanned to verify that it does not contain any rows which properly
belong in the new partition. If the default partition contains a
large number of rows, this may be slow. The scan will be skipped if
the default partition is a foreign table or if it has a constraint which
proves that it cannot contain rows which should be placed in the new
partition.
</para>
<para>
A partition must have the same column names and types as the partitioned
table to which it belongs. If the parent is specified <literal>WITH
......@@ -1679,6 +1701,13 @@ CREATE TABLE cities_ab
CREATE TABLE cities_ab_10000_to_100000
PARTITION OF cities_ab FOR VALUES FROM (10000) TO (100000);
</programlisting></para>
<para>
Create a default partition:
<programlisting>
CREATE TABLE cities_partdef
PARTITION OF cities DEFAULT;
</programlisting></para>
</refsect1>
<refsect1 id="SQL-CREATETABLE-compatibility">
......
......@@ -1759,7 +1759,8 @@ heap_drop_with_catalog(Oid relid)
{
Relation rel;
HeapTuple tuple;
Oid parentOid = InvalidOid;
Oid parentOid = InvalidOid,
defaultPartOid = InvalidOid;
/*
* To drop a partition safely, we must grab exclusive lock on its parent,
......@@ -1775,6 +1776,14 @@ heap_drop_with_catalog(Oid relid)
{
parentOid = get_partition_parent(relid);
LockRelationOid(parentOid, AccessExclusiveLock);
/*
* If this is not the default partition, dropping it will change the
* default partition's partition constraint, so we must lock it.
*/
defaultPartOid = get_default_partition_oid(parentOid);
if (OidIsValid(defaultPartOid) && relid != defaultPartOid)
LockRelationOid(defaultPartOid, AccessExclusiveLock);
}
ReleaseSysCache(tuple);
......@@ -1825,6 +1834,13 @@ heap_drop_with_catalog(Oid relid)
if (rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE)
RemovePartitionKeyByRelId(relid);
/*
* If the relation being dropped is the default partition itself,
* invalidate its entry in pg_partitioned_table.
*/
if (relid == defaultPartOid)
update_default_partition_oid(parentOid, InvalidOid);
/*
* Schedule unlinking of the relation's physical files at commit.
*/
......@@ -1884,6 +1900,14 @@ heap_drop_with_catalog(Oid relid)
if (OidIsValid(parentOid))
{
/*
* If this is not the default partition, the partition constraint of
* the default partition has changed to include the portion of the key
* space previously covered by the dropped partition.
*/
if (OidIsValid(defaultPartOid) && relid != defaultPartOid)
CacheInvalidateRelcacheByRelid(defaultPartOid);
/*
* Invalidate the parent's relcache so that the partition is no longer
* included in its partition descriptor.
......@@ -3138,6 +3162,7 @@ StorePartitionKey(Relation rel,
values[Anum_pg_partitioned_table_partrelid - 1] = ObjectIdGetDatum(RelationGetRelid(rel));
values[Anum_pg_partitioned_table_partstrat - 1] = CharGetDatum(strategy);
values[Anum_pg_partitioned_table_partnatts - 1] = Int16GetDatum(partnatts);
values[Anum_pg_partitioned_table_partdefid - 1] = ObjectIdGetDatum(InvalidOid);
values[Anum_pg_partitioned_table_partattrs - 1] = PointerGetDatum(partattrs_vec);
values[Anum_pg_partitioned_table_partclass - 1] = PointerGetDatum(partopclass_vec);
values[Anum_pg_partitioned_table_partcollation - 1] = PointerGetDatum(partcollation_vec);
......@@ -3223,7 +3248,8 @@ RemovePartitionKeyByRelId(Oid relid)
* relispartition to true
*
* Also, invalidate the parent's relcache, so that the next rebuild will load
* the new partition's info into its partition descriptor.
* the new partition's info into its partition descriptor.  If there is a
* default partition, we must invalidate its relcache entry as well.
*/
void
StorePartitionBound(Relation rel, Relation parent, PartitionBoundSpec *bound)
......@@ -3234,6 +3260,7 @@ StorePartitionBound(Relation rel, Relation parent, PartitionBoundSpec *bound)
Datum new_val[Natts_pg_class];
bool new_null[Natts_pg_class],
new_repl[Natts_pg_class];
Oid defaultPartOid;
/* Update pg_class tuple */
classRel = heap_open(RelationRelationId, RowExclusiveLock);
......@@ -3271,5 +3298,15 @@ StorePartitionBound(Relation rel, Relation parent, PartitionBoundSpec *bound)
heap_freetuple(newtuple);
heap_close(classRel, RowExclusiveLock);
/*
* The partition constraint for the default partition depends on the
* partition bounds of every other partition, so we must invalidate the
* relcache entry for that partition every time a partition is added or
* removed.
*/
defaultPartOid = get_default_oid_from_partdesc(RelationGetPartitionDesc(parent));
if (OidIsValid(defaultPartOid))
CacheInvalidateRelcacheByRelid(defaultPartOid);
CacheInvalidateRelcache(parent);
}
This diff is collapsed.
This diff is collapsed.
......@@ -4450,6 +4450,7 @@ _copyPartitionBoundSpec(const PartitionBoundSpec *from)
PartitionBoundSpec *newnode = makeNode(PartitionBoundSpec);
COPY_SCALAR_FIELD(strategy);
COPY_SCALAR_FIELD(is_default);
COPY_NODE_FIELD(listdatums);
COPY_NODE_FIELD(lowerdatums);
COPY_NODE_FIELD(upperdatums);
......
......@@ -2839,6 +2839,7 @@ static bool
_equalPartitionBoundSpec(const PartitionBoundSpec *a, const PartitionBoundSpec *b)
{
COMPARE_SCALAR_FIELD(strategy);
COMPARE_SCALAR_FIELD(is_default);
COMPARE_NODE_FIELD(listdatums);
COMPARE_NODE_FIELD(lowerdatums);
COMPARE_NODE_FIELD(upperdatums);
......
......@@ -3573,6 +3573,7 @@ _outPartitionBoundSpec(StringInfo str, const PartitionBoundSpec *node)
WRITE_NODE_TYPE("PARTITIONBOUNDSPEC");
WRITE_CHAR_FIELD(strategy);
WRITE_BOOL_FIELD(is_default);
WRITE_NODE_FIELD(listdatums);
WRITE_NODE_FIELD(lowerdatums);
WRITE_NODE_FIELD(upperdatums);
......
......@@ -2390,6 +2390,7 @@ _readPartitionBoundSpec(void)
READ_LOCALS(PartitionBoundSpec);
READ_CHAR_FIELD(strategy);
READ_BOOL_FIELD(is_default);
READ_NODE_FIELD(listdatums);
READ_NODE_FIELD(lowerdatums);
READ_NODE_FIELD(upperdatums);
......
......@@ -575,7 +575,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <str> part_strategy
%type <partelem> part_elem
%type <list> part_params
%type <partboundspec> ForValues
%type <partboundspec> PartitionBoundSpec
%type <node> partbound_datum PartitionRangeDatum
%type <list> partbound_datum_list range_datum_list
......@@ -1980,7 +1980,7 @@ alter_table_cmds:
partition_cmd:
/* ALTER TABLE <name> ATTACH PARTITION <table_name> FOR VALUES */
ATTACH PARTITION qualified_name ForValues
ATTACH PARTITION qualified_name PartitionBoundSpec
{
AlterTableCmd *n = makeNode(AlterTableCmd);
PartitionCmd *cmd = makeNode(PartitionCmd);
......@@ -2635,13 +2635,14 @@ alter_identity_column_option:
}
;
ForValues:
PartitionBoundSpec:
/* a LIST partition */
FOR VALUES IN_P '(' partbound_datum_list ')'
{
PartitionBoundSpec *n = makeNode(PartitionBoundSpec);
n->strategy = PARTITION_STRATEGY_LIST;
n->is_default = false;
n->listdatums = $5;
n->location = @3;
......@@ -2654,10 +2655,22 @@ ForValues:
PartitionBoundSpec *n = makeNode(PartitionBoundSpec);
n->strategy = PARTITION_STRATEGY_RANGE;
n->is_default = false;
n->lowerdatums = $5;
n->upperdatums = $9;
n->location = @3;
$$ = n;
}
/* a DEFAULT partition */
| DEFAULT
{
PartitionBoundSpec *n = makeNode(PartitionBoundSpec);
n->is_default = true;
n->location = @1;
$$ = n;
}
;
......@@ -3130,7 +3143,7 @@ CreateStmt: CREATE OptTemp TABLE qualified_name '(' OptTableElementList ')'
$$ = (Node *)n;
}
| CREATE OptTemp TABLE qualified_name PARTITION OF qualified_name
OptTypedTableElementList ForValues OptPartitionSpec OptWith
OptTypedTableElementList PartitionBoundSpec OptPartitionSpec OptWith
OnCommitOption OptTableSpace
{
CreateStmt *n = makeNode(CreateStmt);
......@@ -3149,7 +3162,7 @@ CreateStmt: CREATE OptTemp TABLE qualified_name '(' OptTableElementList ')'
$$ = (Node *)n;
}
| CREATE OptTemp TABLE IF_P NOT EXISTS qualified_name PARTITION OF
qualified_name OptTypedTableElementList ForValues OptPartitionSpec
qualified_name OptTypedTableElementList PartitionBoundSpec OptPartitionSpec
OptWith OnCommitOption OptTableSpace
{
CreateStmt *n = makeNode(CreateStmt);
......@@ -4864,7 +4877,7 @@ CreateForeignTableStmt:
$$ = (Node *) n;
}
| CREATE FOREIGN TABLE qualified_name
PARTITION OF qualified_name OptTypedTableElementList ForValues
PARTITION OF qualified_name OptTypedTableElementList PartitionBoundSpec
SERVER name create_generic_options
{
CreateForeignTableStmt *n = makeNode(CreateForeignTableStmt);
......@@ -4885,7 +4898,7 @@ CreateForeignTableStmt:
$$ = (Node *) n;
}
| CREATE FOREIGN TABLE IF_P NOT EXISTS qualified_name
PARTITION OF qualified_name OptTypedTableElementList ForValues
PARTITION OF qualified_name OptTypedTableElementList PartitionBoundSpec
SERVER name create_generic_options
{
CreateForeignTableStmt *n = makeNode(CreateForeignTableStmt);
......
......@@ -3307,6 +3307,18 @@ transformPartitionBound(ParseState *pstate, Relation parent,
/* Avoid scribbling on input */
result_spec = copyObject(spec);
if (spec->is_default)
{
/*
* In case of the default partition, parser had no way to identify the
* partition strategy. Assign the parent's strategy to the default
* partition bound spec.
*/
result_spec->strategy = strategy;
return result_spec;
}
if (strategy == PARTITION_STRATEGY_LIST)
{
ListCell *cell;
......
......@@ -1750,7 +1750,7 @@ pg_get_partition_constraintdef(PG_FUNCTION_ARGS)
constr_expr = get_partition_qual_relid(relationId);
/* Quick exit if not a partition */
/* Quick exit if no partition constraint */
if (constr_expr == NULL)
PG_RETURN_NULL();
......@@ -8699,6 +8699,12 @@ get_rule_expr(Node *node, deparse_context *context,
ListCell *cell;
char *sep;
if (spec->is_default)
{
appendStringInfoString(buf, "DEFAULT");
break;
}
switch (spec->strategy)
{
case PARTITION_STRATEGY_LIST:
......
......@@ -1893,19 +1893,20 @@ describeOneTableDetails(const char *schemaname,
parent_name = PQgetvalue(result, 0, 0);
partdef = PQgetvalue(result, 0, 1);
if (PQnfields(result) == 3)
if (PQnfields(result) == 3 && !PQgetisnull(result, 0, 2))
partconstraintdef = PQgetvalue(result, 0, 2);
printfPQExpBuffer(&tmpbuf, _("Partition of: %s %s"), parent_name,
partdef);
printTableAddFooter(&cont, tmpbuf.data);
if (partconstraintdef)
{
/* If there isn't any constraint, show that explicitly */
if (partconstraintdef == NULL || partconstraintdef[0] == '\0')
printfPQExpBuffer(&tmpbuf, _("No partition constraint"));
else
printfPQExpBuffer(&tmpbuf, _("Partition constraint: %s"),
partconstraintdef);
printTableAddFooter(&cont, tmpbuf.data);
}
PQclear(result);
}
......
......@@ -2053,7 +2053,7 @@ psql_completion(const char *text, int start, int end)
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_tables, "");
/* Limited completion support for partition bound specification */
else if (TailMatches3("ATTACH", "PARTITION", MatchAny))
COMPLETE_WITH_CONST("FOR VALUES");
COMPLETE_WITH_LIST2("FOR VALUES", "DEFAULT");
else if (TailMatches2("FOR", "VALUES"))
COMPLETE_WITH_LIST2("FROM (", "IN (");
......@@ -2492,7 +2492,7 @@ psql_completion(const char *text, int start, int end)
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_partitioned_tables, "");
/* Limited completion support for partition bound specification */
else if (TailMatches3("PARTITION", "OF", MatchAny))
COMPLETE_WITH_CONST("FOR VALUES");
COMPLETE_WITH_LIST2("FOR VALUES", "DEFAULT");
/* CREATE TABLESPACE */
else if (Matches3("CREATE", "TABLESPACE", MatchAny))
......
......@@ -53,6 +53,6 @@
*/
/* yyyymmddN */
#define CATALOG_VERSION_NO 201708311
#define CATALOG_VERSION_NO 201709081
#endif
......@@ -99,4 +99,11 @@ extern int get_partition_for_tuple(PartitionDispatch *pd,
EState *estate,
PartitionDispatchData **failed_at,
TupleTableSlot **failed_slot);
extern Oid get_default_oid_from_partdesc(PartitionDesc partdesc);
extern Oid get_default_partition_oid(Oid parentId);
extern void update_default_partition_oid(Oid parentId, Oid defaultPartId);
extern void check_default_allows_bound(Relation parent, Relation defaultRel,
PartitionBoundSpec *new_spec);
extern List *get_proposed_default_constraint(List *new_part_constaints);
#endif /* PARTITION_H */
......@@ -32,6 +32,8 @@ CATALOG(pg_partitioned_table,3350) BKI_WITHOUT_OIDS
Oid partrelid; /* partitioned table oid */
char partstrat; /* partitioning strategy */
int16 partnatts; /* number of partition key columns */
Oid partdefid; /* default partition oid; InvalidOid if there
* isn't one */
/*
* variable-length fields start here, but we allow direct access to
......@@ -62,13 +64,14 @@ typedef FormData_pg_partitioned_table *Form_pg_partitioned_table;
* compiler constants for pg_partitioned_table
* ----------------
*/
#define Natts_pg_partitioned_table 7
#define Natts_pg_partitioned_table 8
#define Anum_pg_partitioned_table_partrelid 1
#define Anum_pg_partitioned_table_partstrat 2
#define Anum_pg_partitioned_table_partnatts 3
#define Anum_pg_partitioned_table_partattrs 4
#define Anum_pg_partitioned_table_partclass 5
#define Anum_pg_partitioned_table_partcollation 6
#define Anum_pg_partitioned_table_partexprs 7
#define Anum_pg_partitioned_table_partdefid 4
#define Anum_pg_partitioned_table_partattrs 5
#define Anum_pg_partitioned_table_partclass 6
#define Anum_pg_partitioned_table_partcollation 7
#define Anum_pg_partitioned_table_partexprs 8
#endif /* PG_PARTITIONED_TABLE_H */
......@@ -18,6 +18,7 @@
#include "catalog/dependency.h"
#include "catalog/objectaddress.h"
#include "nodes/parsenodes.h"
#include "catalog/partition.h"
#include "storage/lock.h"
#include "utils/relcache.h"
......@@ -87,4 +88,7 @@ extern void RangeVarCallbackOwnsTable(const RangeVar *relation,
extern void RangeVarCallbackOwnsRelation(const RangeVar *relation,
Oid relId, Oid oldRelId, void *noCatalogs);
extern bool PartConstraintImpliedByRelConstraint(Relation scanrel,
List *partConstraint);
#endif /* TABLECMDS_H */
......@@ -797,6 +797,7 @@ typedef struct PartitionBoundSpec
NodeTag type;
char strategy; /* see PARTITION_STRATEGY codes above */
bool is_default; /* is it a default partition bound? */
/* Partitioning info for LIST strategy: */
List *listdatums; /* List of Consts (or A_Consts in raw tree) */
......
......@@ -3297,6 +3297,14 @@ SELECT conislocal, coninhcount FROM pg_constraint WHERE conrelid = 'part_1'::reg
CREATE TABLE fail_part (LIKE part_1 INCLUDING CONSTRAINTS);
ALTER TABLE list_parted ATTACH PARTITION fail_part FOR VALUES IN (1);
ERROR: partition "fail_part" would overlap partition "part_1"
-- check that an existing table can be attached as a default partition
CREATE TABLE def_part (LIKE list_parted INCLUDING CONSTRAINTS);
ALTER TABLE list_parted ATTACH PARTITION def_part DEFAULT;
-- check attaching default partition fails if a default partition already
-- exists
CREATE TABLE fail_def_part (LIKE part_1 INCLUDING CONSTRAINTS);
ALTER TABLE list_parted ATTACH PARTITION fail_def_part DEFAULT;
ERROR: partition "fail_def_part" conflicts with existing default partition "def_part"
-- check validation when attaching list partitions
CREATE TABLE list_parted2 (
a int,
......@@ -3310,6 +3318,15 @@ ERROR: partition constraint is violated by some row
-- should be ok after deleting the bad row
DELETE FROM part_2;
ALTER TABLE list_parted2 ATTACH PARTITION part_2 FOR VALUES IN (2);
-- check partition cannot be attached if default has some row for its values
CREATE TABLE list_parted2_def PARTITION OF list_parted2 DEFAULT;
INSERT INTO list_parted2_def VALUES (11, 'z');
CREATE TABLE part_3 (LIKE list_parted2);
ALTER TABLE list_parted2 ATTACH PARTITION part_3 FOR VALUES IN (11);
ERROR: updated partition constraint for default partition would be violated by some row
-- should be ok after deleting the bad row
DELETE FROM list_parted2_def WHERE a = 11;
ALTER TABLE list_parted2 ATTACH PARTITION part_3 FOR VALUES IN (11);
-- adding constraints that describe the desired partition constraint
-- (or more restrictive) will help skip the validation scan
CREATE TABLE part_3_4 (
......@@ -3325,6 +3342,10 @@ ALTER TABLE list_parted2 DETACH PARTITION part_3_4;
ALTER TABLE part_3_4 ALTER a SET NOT NULL;
ALTER TABLE list_parted2 ATTACH PARTITION part_3_4 FOR VALUES IN (3, 4);
INFO: partition constraint for table "part_3_4" is implied by existing constraints
-- check if default partition scan skipped
ALTER TABLE list_parted2_def ADD CONSTRAINT check_a CHECK (a IN (5, 6));
CREATE TABLE part_55_66 PARTITION OF list_parted2 FOR VALUES IN (55, 66);
INFO: partition constraint for table "list_parted2_def" is implied by existing constraints
-- check validation when attaching range partitions
CREATE TABLE range_parted (
a int,
......@@ -3350,6 +3371,19 @@ CREATE TABLE part2 (
);
ALTER TABLE range_parted ATTACH PARTITION part2 FOR VALUES FROM (1, 10) TO (1, 20);
INFO: partition constraint for table "part2" is implied by existing constraints
-- Create default partition
CREATE TABLE partr_def1 PARTITION OF range_parted DEFAULT;
-- Only one default partition is allowed, hence, following should give error
CREATE TABLE partr_def2 (LIKE part1 INCLUDING CONSTRAINTS);
ALTER TABLE range_parted ATTACH PARTITION partr_def2 DEFAULT;
ERROR: partition "partr_def2" conflicts with existing default partition "partr_def1"
-- Overlapping partitions cannot be attached, hence, following should give error
INSERT INTO partr_def1 VALUES (2, 10);
CREATE TABLE part3 (LIKE range_parted);
ALTER TABLE range_parted ATTACH partition part3 FOR VALUES FROM (2, 10) TO (2, 20);
ERROR: updated partition constraint for default partition would be violated by some row
-- Attaching partitions should be successful when there are no overlapping rows
ALTER TABLE range_parted ATTACH partition part3 FOR VALUES FROM (3, 10) TO (3, 20);
-- check that leaf partitions are scanned when attaching a partitioned
-- table
CREATE TABLE part_5 (
......@@ -3402,6 +3436,7 @@ ALTER TABLE part_7 ATTACH PARTITION part_7_a_null FOR VALUES IN ('a', null);
INFO: partition constraint for table "part_7_a_null" is implied by existing constraints
ALTER TABLE list_parted2 ATTACH PARTITION part_7 FOR VALUES IN (7);
INFO: partition constraint for table "part_7" is implied by existing constraints
INFO: partition constraint for table "list_parted2_def" is implied by existing constraints
-- Same example, but check this time that the constraint correctly detects
-- violating rows
ALTER TABLE list_parted2 DETACH PARTITION part_7;
......@@ -3415,7 +3450,20 @@ SELECT tableoid::regclass, a, b FROM part_7 order by a;
(2 rows)
ALTER TABLE list_parted2 ATTACH PARTITION part_7 FOR VALUES IN (7);
INFO: partition constraint for table "list_parted2_def" is implied by existing constraints
ERROR: partition constraint is violated by some row
-- check that leaf partitions of default partition are scanned when
-- attaching a partitioned table.
ALTER TABLE part_5 DROP CONSTRAINT check_a;
CREATE TABLE part5_def PARTITION OF part_5 DEFAULT PARTITION BY LIST(a);
CREATE TABLE part5_def_p1 PARTITION OF part5_def FOR VALUES IN (5);
INSERT INTO part5_def_p1 VALUES (5, 'y');
CREATE TABLE part5_p1 (LIKE part_5);
ALTER TABLE part_5 ATTACH PARTITION part5_p1 FOR VALUES IN ('y');
ERROR: updated partition constraint for default partition would be violated by some row
-- should be ok after deleting the bad row
DELETE FROM part5_def_p1 WHERE b = 'y';
ALTER TABLE part_5 ATTACH PARTITION part5_p1 FOR VALUES IN ('y');
-- check that the table being attached is not already a partition
ALTER TABLE list_parted2 ATTACH PARTITION part_2 FOR VALUES IN (2);
ERROR: "part_2" is already a partition
......@@ -3538,6 +3586,7 @@ ALTER TABLE list_parted2 ALTER COLUMN b TYPE text;
ERROR: cannot alter type of column named in partition key
-- cleanup
DROP TABLE list_parted, list_parted2, range_parted;
DROP TABLE fail_def_part;
-- more tests for certain multi-level partitioning scenarios
create table p (a int, b int) partition by range (a, b);
create table p1 (b int, a int not null) partition by range (b);
......
......@@ -467,6 +467,10 @@ CREATE TABLE fail_part PARTITION OF list_parted FOR VALUES FROM (1) TO (2);
ERROR: invalid bound specification for a list partition
LINE 1: ...BLE fail_part PARTITION OF list_parted FOR VALUES FROM (1) T...
^
-- check default partition cannot be created more than once
CREATE TABLE part_default PARTITION OF list_parted DEFAULT;
CREATE TABLE fail_default_part PARTITION OF list_parted DEFAULT;
ERROR: partition "fail_default_part" conflicts with existing default partition "part_default"
-- specified literal can't be cast to the partition column data type
CREATE TABLE bools (
a bool
......@@ -558,10 +562,15 @@ CREATE TABLE list_parted2 (
) PARTITION BY LIST (a);
CREATE TABLE part_null_z PARTITION OF list_parted2 FOR VALUES IN (null, 'z');
CREATE TABLE part_ab PARTITION OF list_parted2 FOR VALUES IN ('a', 'b');
CREATE TABLE list_parted2_def PARTITION OF list_parted2 DEFAULT;
CREATE TABLE fail_part PARTITION OF list_parted2 FOR VALUES IN (null);
ERROR: partition "fail_part" would overlap partition "part_null_z"
CREATE TABLE fail_part PARTITION OF list_parted2 FOR VALUES IN ('b', 'c');
ERROR: partition "fail_part" would overlap partition "part_ab"
-- check default partition overlap
INSERT INTO list_parted2 VALUES('X');
CREATE TABLE fail_part PARTITION OF list_parted2 FOR VALUES IN ('W', 'X', 'Y');
ERROR: updated partition constraint for default partition "list_parted2_def" would be violated by some row
CREATE TABLE range_parted2 (
a int
) PARTITION BY RANGE (a);
......@@ -585,6 +594,16 @@ CREATE TABLE fail_part PARTITION OF range_parted2 FOR VALUES FROM (10) TO (30);
ERROR: partition "fail_part" would overlap partition "part2"
CREATE TABLE fail_part PARTITION OF range_parted2 FOR VALUES FROM (10) TO (50);
ERROR: partition "fail_part" would overlap partition "part2"
-- Create a default partition for range partitioned table
CREATE TABLE range2_default PARTITION OF range_parted2 DEFAULT;
-- More than one default partition is not allowed, so this should give error
CREATE TABLE fail_default_part PARTITION OF range_parted2 DEFAULT;
ERROR: partition "fail_default_part" conflicts with existing default partition "range2_default"
-- Check if the range for default partitions overlap
INSERT INTO range_parted2 VALUES (85);
CREATE TABLE fail_part PARTITION OF range_parted2 FOR VALUES FROM (80) TO (90);
ERROR: updated partition constraint for default partition "range2_default" would be violated by some row
CREATE TABLE part4 PARTITION OF range_parted2 FOR VALUES FROM (90) TO (100);
-- now check for multi-column range partition key
CREATE TABLE range_parted3 (
a int,
......@@ -598,6 +617,7 @@ CREATE TABLE part11 PARTITION OF range_parted3 FOR VALUES FROM (1, 1) TO (1, 10)
CREATE TABLE part12 PARTITION OF range_parted3 FOR VALUES FROM (1, 10) TO (1, maxvalue);
CREATE TABLE fail_part PARTITION OF range_parted3 FOR VALUES FROM (1, 10) TO (1, 20);
ERROR: partition "fail_part" would overlap partition "part12"
CREATE TABLE range3_default PARTITION OF range_parted3 DEFAULT;
-- cannot create a partition that says column b is allowed to range
-- from -infinity to +infinity, while there exist partitions that have
-- more specific ranges
......
......@@ -219,17 +219,63 @@ insert into part_null values (null, 0);
create table part_ee_ff partition of list_parted for values in ('ee', 'ff') partition by range (b);
create table part_ee_ff1 partition of part_ee_ff for values from (1) to (10);
create table part_ee_ff2 partition of part_ee_ff for values from (10) to (20);
-- test default partition
create table part_default partition of list_parted default;
-- Negative test: a row, which would fit in other partition, does not fit
-- default partition, even when inserted directly
insert into part_default values ('aa', 2);
ERROR: new row for relation "part_default" violates partition constraint
DETAIL: Failing row contains (aa, 2).
insert into part_default values (null, 2);
ERROR: new row for relation "part_default" violates partition constraint
DETAIL: Failing row contains (null, 2).
-- ok
insert into part_default values ('Zz', 2);
-- test if default partition works as expected for multi-level partitioned
-- table as well as when default partition itself is further partitioned
drop table part_default;
create table part_xx_yy partition of list_parted for values in ('xx', 'yy') partition by list (a);
create table part_xx_yy_p1 partition of part_xx_yy for values in ('xx');
create table part_xx_yy_defpart partition of part_xx_yy default;
create table part_default partition of list_parted default partition by range(b);
create table part_default_p1 partition of part_default for values from (20) to (30);
create table part_default_p2 partition of part_default for values from (30) to (40);
-- fail
insert into part_ee_ff1 values ('EE', 11);
ERROR: new row for relation "part_ee_ff1" violates partition constraint
DETAIL: Failing row contains (EE, 11).
insert into part_default_p2 values ('gg', 43);
ERROR: new row for relation "part_default_p2" violates partition constraint
DETAIL: Failing row contains (gg, 43).
-- fail (even the parent's, ie, part_ee_ff's partition constraint applies)
insert into part_ee_ff1 values ('cc', 1);
ERROR: new row for relation "part_ee_ff1" violates partition constraint
DETAIL: Failing row contains (cc, 1).
insert into part_default values ('gg', 43);
ERROR: no partition of relation "part_default" found for row
DETAIL: Partition key of the failing row contains (b) = (43).
-- ok
insert into part_ee_ff1 values ('ff', 1);
insert into part_ee_ff2 values ('ff', 11);
insert into part_default_p1 values ('cd', 25);
insert into part_default_p2 values ('de', 35);
insert into list_parted values ('ab', 21);
insert into list_parted values ('xx', 1);
insert into list_parted values ('yy', 2);
select tableoid::regclass, * from list_parted;
tableoid | a | b
--------------------+----+----
part_cc_dd | cC | 1
part_ee_ff1 | ff | 1
part_ee_ff2 | ff | 11
part_xx_yy_p1 | xx | 1
part_xx_yy_defpart | yy | 2
part_null | | 0
part_default_p1 | cd | 25
part_default_p1 | ab | 21
part_default_p2 | de | 35
(9 rows)
-- Check tuple routing for partitioned tables
-- fail
insert into range_parted values ('a', 0);
......@@ -249,6 +295,18 @@ insert into range_parted values ('b', 10);
insert into range_parted values ('a');
ERROR: no partition of relation "range_parted" found for row
DETAIL: Partition key of the failing row contains (a, (b + 0)) = (a, null).
-- Check default partition
create table part_def partition of range_parted default;
-- fail
insert into part_def values ('b', 10);
ERROR: new row for relation "part_def" violates partition constraint
DETAIL: Failing row contains (b, 10).
-- ok
insert into part_def values ('c', 10);
insert into range_parted values (null, null);
insert into range_parted values ('a', null);
insert into range_parted values (null, 19);
insert into range_parted values ('b', 20);
select tableoid::regclass, * from range_parted;
tableoid | a | b
----------+---+----
......@@ -258,7 +316,12 @@ select tableoid::regclass, * from range_parted;
part3 | b | 1
part4 | b | 10
part4 | b | 10
(6 rows)
part_def | c | 10
part_def | |
part_def | a |
part_def | | 19
part_def | b | 20
(11 rows)
-- ok
insert into list_parted values (null, 1);
......@@ -275,16 +338,21 @@ insert into list_parted values ('EE', 1);
insert into part_ee_ff values ('EE', 10);
select tableoid::regclass, * from list_parted;
tableoid | a | b
-------------+----+----
--------------------+----+----
part_aa_bb | aA |
part_cc_dd | cC | 1
part_ee_ff1 | ff | 1
part_ee_ff1 | EE | 1
part_ee_ff2 | ff | 11
part_ee_ff2 | EE | 10
part_xx_yy_p1 | xx | 1
part_xx_yy_defpart | yy | 2
part_null | | 0
part_null | | 1
(8 rows)
part_default_p1 | cd | 25
part_default_p1 | ab | 21
part_default_p2 | de | 35
(13 rows)
-- some more tests to exercise tuple-routing with multi-level partitioning
create table part_gg partition of list_parted for values in ('gg') partition by range (b);
......@@ -316,6 +384,31 @@ select tableoid::regclass::text, a, min(b) as min_b, max(b) as max_b from list_p
-- cleanup
drop table range_parted, list_parted;
-- test that a default partition added as the first partition accepts any value
-- including null
create table list_parted (a int) partition by list (a);
create table part_default partition of list_parted default;
\d+ part_default
Table "public.part_default"
Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
--------+---------+-----------+----------+---------+---------+--------------+-------------
a | integer | | | | plain | |
Partition of: list_parted DEFAULT
No partition constraint
insert into part_default values (null);
insert into part_default values (1);
insert into part_default values (-1);
select tableoid::regclass, a from list_parted;
tableoid | a
--------------+----
part_default |
part_default | 1
part_default | -1
(3 rows)
-- cleanup
drop table list_parted;
-- more tests for certain multi-level partitioning scenarios
create table mlparted (a int, b int) partition by range (a, b);
create table mlparted1 (b int not null, a int not null) partition by range ((b+0));
......@@ -425,6 +518,36 @@ insert into mlparted5 (a, b, c) values (1, 40, 'a');
ERROR: new row for relation "mlparted5a" violates partition constraint
DETAIL: Failing row contains (b, 1, 40).
drop table mlparted5;
alter table mlparted drop constraint check_b;
-- Check multi-level default partition
create table mlparted_def partition of mlparted default partition by range(a);
create table mlparted_def1 partition of mlparted_def for values from (40) to (50);
create table mlparted_def2 partition of mlparted_def for values from (50) to (60);
insert into mlparted values (40, 100);
insert into mlparted_def1 values (42, 100);
insert into mlparted_def2 values (54, 50);
-- fail
insert into mlparted values (70, 100);
ERROR: no partition of relation "mlparted_def" found for row
DETAIL: Partition key of the failing row contains (a) = (70).
insert into mlparted_def1 values (52, 50);
ERROR: new row for relation "mlparted_def1" violates partition constraint
DETAIL: Failing row contains (52, 50, null).
insert into mlparted_def2 values (34, 50);
ERROR: new row for relation "mlparted_def2" violates partition constraint
DETAIL: Failing row contains (34, 50, null).
-- ok
create table mlparted_defd partition of mlparted_def default;
insert into mlparted values (70, 100);
select tableoid::regclass, * from mlparted_def;
tableoid | a | b | c
---------------+----+-----+---
mlparted_def1 | 40 | 100 |
mlparted_def1 | 42 | 100 |
mlparted_def2 | 54 | 50 |
mlparted_defd | 70 | 100 |
(4 rows)
-- check that message shown after failure to find a partition shows the
-- appropriate key description (or none) in various situations
create table key_desc (a int, b int) partition by list ((a+0));
......
......@@ -252,3 +252,29 @@ NOTICE: 3
(1 row)
-- Check that addition or removal of any partition is correctly dealt with by
-- default partition table when it is being used in prepared statement.
create table list_parted (a int) partition by list(a);
create table list_part_null partition of list_parted for values in (null);
create table list_part_1 partition of list_parted for values in (1);
create table list_part_def partition of list_parted default;
prepare pstmt_def_insert (int) as insert into list_part_def values($1);
-- should fail
execute pstmt_def_insert(null);
ERROR: new row for relation "list_part_def" violates partition constraint
DETAIL: Failing row contains (null).
execute pstmt_def_insert(1);
ERROR: new row for relation "list_part_def" violates partition constraint
DETAIL: Failing row contains (1).
create table list_part_2 partition of list_parted for values in (2);
execute pstmt_def_insert(2);
ERROR: new row for relation "list_part_def" violates partition constraint
DETAIL: Failing row contains (2).
alter table list_parted detach partition list_part_null;
-- should be ok
execute pstmt_def_insert(null);
drop table list_part_1;
-- should be ok
execute pstmt_def_insert(1);
drop table list_parted, list_part_null;
deallocate pstmt_def_insert;
......@@ -77,6 +77,10 @@ mlparted12|f
mlparted2|f
mlparted3|f
mlparted4|f
mlparted_def|f
mlparted_def1|f
mlparted_def2|f
mlparted_defd|f
money_data|f
num_data|f
num_exp_add|t
......
......@@ -218,5 +218,38 @@ ERROR: new row for relation "part_b_10_b_20" violates partition constraint
DETAIL: Failing row contains (b, 9).
-- ok
update range_parted set b = b + 1 where b = 10;
-- Creating default partition for range
create table part_def partition of range_parted default;
\d+ part_def
Table "public.part_def"
Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
--------+---------+-----------+----------+---------+----------+--------------+-------------
a | text | | | | extended | |
b | integer | | | | plain | |
Partition of: range_parted DEFAULT
Partition constraint: (NOT (((a = 'a'::text) AND (b >= 1) AND (b < 10)) OR ((a = 'a'::text) AND (b >= 10) AND (b < 20)) OR ((a = 'b'::text) AND (b >= 1) AND (b < 10)) OR ((a = 'b'::text) AND (b >= 10) AND (b < 20))))
insert into range_parted values ('c', 9);
-- ok
update part_def set a = 'd' where a = 'c';
-- fail
update part_def set a = 'a' where a = 'd';
ERROR: new row for relation "part_def" violates partition constraint
DETAIL: Failing row contains (a, 9).
create table list_parted (
a text,
b int
) partition by list (a);
create table list_part1 partition of list_parted for values in ('a', 'b');
create table list_default partition of list_parted default;
insert into list_part1 values ('a', 1);
insert into list_default values ('d', 10);
-- fail
update list_default set a = 'a' where a = 'd';
ERROR: new row for relation "list_default" violates partition constraint
DETAIL: Failing row contains (a, 10).
-- ok
update list_default set a = 'x' where a = 'd';
-- cleanup
drop table range_parted;
drop table list_parted;
......@@ -2111,6 +2111,13 @@ SELECT conislocal, coninhcount FROM pg_constraint WHERE conrelid = 'part_1'::reg
-- check that the new partition won't overlap with an existing partition
CREATE TABLE fail_part (LIKE part_1 INCLUDING CONSTRAINTS);
ALTER TABLE list_parted ATTACH PARTITION fail_part FOR VALUES IN (1);
-- check that an existing table can be attached as a default partition
CREATE TABLE def_part (LIKE list_parted INCLUDING CONSTRAINTS);
ALTER TABLE list_parted ATTACH PARTITION def_part DEFAULT;
-- check attaching default partition fails if a default partition already
-- exists
CREATE TABLE fail_def_part (LIKE part_1 INCLUDING CONSTRAINTS);
ALTER TABLE list_parted ATTACH PARTITION fail_def_part DEFAULT;
-- check validation when attaching list partitions
CREATE TABLE list_parted2 (
......@@ -2127,6 +2134,15 @@ ALTER TABLE list_parted2 ATTACH PARTITION part_2 FOR VALUES IN (2);
DELETE FROM part_2;
ALTER TABLE list_parted2 ATTACH PARTITION part_2 FOR VALUES IN (2);
-- check partition cannot be attached if default has some row for its values
CREATE TABLE list_parted2_def PARTITION OF list_parted2 DEFAULT;
INSERT INTO list_parted2_def VALUES (11, 'z');
CREATE TABLE part_3 (LIKE list_parted2);
ALTER TABLE list_parted2 ATTACH PARTITION part_3 FOR VALUES IN (11);
-- should be ok after deleting the bad row
DELETE FROM list_parted2_def WHERE a = 11;
ALTER TABLE list_parted2 ATTACH PARTITION part_3 FOR VALUES IN (11);
-- adding constraints that describe the desired partition constraint
-- (or more restrictive) will help skip the validation scan
CREATE TABLE part_3_4 (
......@@ -2144,6 +2160,9 @@ ALTER TABLE list_parted2 DETACH PARTITION part_3_4;
ALTER TABLE part_3_4 ALTER a SET NOT NULL;
ALTER TABLE list_parted2 ATTACH PARTITION part_3_4 FOR VALUES IN (3, 4);
-- check if default partition scan skipped
ALTER TABLE list_parted2_def ADD CONSTRAINT check_a CHECK (a IN (5, 6));
CREATE TABLE part_55_66 PARTITION OF list_parted2 FOR VALUES IN (55, 66);
-- check validation when attaching range partitions
CREATE TABLE range_parted (
......@@ -2172,6 +2191,21 @@ CREATE TABLE part2 (
);
ALTER TABLE range_parted ATTACH PARTITION part2 FOR VALUES FROM (1, 10) TO (1, 20);
-- Create default partition
CREATE TABLE partr_def1 PARTITION OF range_parted DEFAULT;
-- Only one default partition is allowed, hence, following should give error
CREATE TABLE partr_def2 (LIKE part1 INCLUDING CONSTRAINTS);
ALTER TABLE range_parted ATTACH PARTITION partr_def2 DEFAULT;
-- Overlapping partitions cannot be attached, hence, following should give error
INSERT INTO partr_def1 VALUES (2, 10);
CREATE TABLE part3 (LIKE range_parted);
ALTER TABLE range_parted ATTACH partition part3 FOR VALUES FROM (2, 10) TO (2, 20);
-- Attaching partitions should be successful when there are no overlapping rows
ALTER TABLE range_parted ATTACH partition part3 FOR VALUES FROM (3, 10) TO (3, 20);
-- check that leaf partitions are scanned when attaching a partitioned
-- table
CREATE TABLE part_5 (
......@@ -2232,6 +2266,18 @@ INSERT INTO part_7 (a, b) VALUES (8, null), (9, 'a');
SELECT tableoid::regclass, a, b FROM part_7 order by a;
ALTER TABLE list_parted2 ATTACH PARTITION part_7 FOR VALUES IN (7);
-- check that leaf partitions of default partition are scanned when
-- attaching a partitioned table.
ALTER TABLE part_5 DROP CONSTRAINT check_a;
CREATE TABLE part5_def PARTITION OF part_5 DEFAULT PARTITION BY LIST(a);
CREATE TABLE part5_def_p1 PARTITION OF part5_def FOR VALUES IN (5);
INSERT INTO part5_def_p1 VALUES (5, 'y');
CREATE TABLE part5_p1 (LIKE part_5);
ALTER TABLE part_5 ATTACH PARTITION part5_p1 FOR VALUES IN ('y');
-- should be ok after deleting the bad row
DELETE FROM part5_def_p1 WHERE b = 'y';
ALTER TABLE part_5 ATTACH PARTITION part5_p1 FOR VALUES IN ('y');
-- check that the table being attached is not already a partition
ALTER TABLE list_parted2 ATTACH PARTITION part_2 FOR VALUES IN (2);
......@@ -2327,6 +2373,7 @@ ALTER TABLE list_parted2 ALTER COLUMN b TYPE text;
-- cleanup
DROP TABLE list_parted, list_parted2, range_parted;
DROP TABLE fail_def_part;
-- more tests for certain multi-level partitioning scenarios
create table p (a int, b int) partition by range (a, b);
......
......@@ -447,6 +447,10 @@ CREATE TABLE fail_part PARTITION OF list_parted FOR VALUES IN ();
-- trying to specify range for list partitioned table
CREATE TABLE fail_part PARTITION OF list_parted FOR VALUES FROM (1) TO (2);
-- check default partition cannot be created more than once
CREATE TABLE part_default PARTITION OF list_parted DEFAULT;
CREATE TABLE fail_default_part PARTITION OF list_parted DEFAULT;
-- specified literal can't be cast to the partition column data type
CREATE TABLE bools (
a bool
......@@ -524,9 +528,13 @@ CREATE TABLE list_parted2 (
) PARTITION BY LIST (a);
CREATE TABLE part_null_z PARTITION OF list_parted2 FOR VALUES IN (null, 'z');
CREATE TABLE part_ab PARTITION OF list_parted2 FOR VALUES IN ('a', 'b');
CREATE TABLE list_parted2_def PARTITION OF list_parted2 DEFAULT;
CREATE TABLE fail_part PARTITION OF list_parted2 FOR VALUES IN (null);
CREATE TABLE fail_part PARTITION OF list_parted2 FOR VALUES IN ('b', 'c');
-- check default partition overlap
INSERT INTO list_parted2 VALUES('X');
CREATE TABLE fail_part PARTITION OF list_parted2 FOR VALUES IN ('W', 'X', 'Y');
CREATE TABLE range_parted2 (
a int
......@@ -546,6 +554,17 @@ CREATE TABLE part3 PARTITION OF range_parted2 FOR VALUES FROM (30) TO (40);
CREATE TABLE fail_part PARTITION OF range_parted2 FOR VALUES FROM (10) TO (30);
CREATE TABLE fail_part PARTITION OF range_parted2 FOR VALUES FROM (10) TO (50);
-- Create a default partition for range partitioned table
CREATE TABLE range2_default PARTITION OF range_parted2 DEFAULT;
-- More than one default partition is not allowed, so this should give error
CREATE TABLE fail_default_part PARTITION OF range_parted2 DEFAULT;
-- Check if the range for default partitions overlap
INSERT INTO range_parted2 VALUES (85);
CREATE TABLE fail_part PARTITION OF range_parted2 FOR VALUES FROM (80) TO (90);
CREATE TABLE part4 PARTITION OF range_parted2 FOR VALUES FROM (90) TO (100);
-- now check for multi-column range partition key
CREATE TABLE range_parted3 (
a int,
......@@ -559,6 +578,7 @@ CREATE TABLE part10 PARTITION OF range_parted3 FOR VALUES FROM (1, minvalue) TO
CREATE TABLE part11 PARTITION OF range_parted3 FOR VALUES FROM (1, 1) TO (1, 10);
CREATE TABLE part12 PARTITION OF range_parted3 FOR VALUES FROM (1, 10) TO (1, maxvalue);
CREATE TABLE fail_part PARTITION OF range_parted3 FOR VALUES FROM (1, 10) TO (1, 20);
CREATE TABLE range3_default PARTITION OF range_parted3 DEFAULT;
-- cannot create a partition that says column b is allowed to range
-- from -infinity to +infinity, while there exist partitions that have
......
......@@ -132,13 +132,39 @@ create table part_ee_ff partition of list_parted for values in ('ee', 'ff') part
create table part_ee_ff1 partition of part_ee_ff for values from (1) to (10);
create table part_ee_ff2 partition of part_ee_ff for values from (10) to (20);
-- test default partition
create table part_default partition of list_parted default;
-- Negative test: a row, which would fit in other partition, does not fit
-- default partition, even when inserted directly
insert into part_default values ('aa', 2);
insert into part_default values (null, 2);
-- ok
insert into part_default values ('Zz', 2);
-- test if default partition works as expected for multi-level partitioned
-- table as well as when default partition itself is further partitioned
drop table part_default;
create table part_xx_yy partition of list_parted for values in ('xx', 'yy') partition by list (a);
create table part_xx_yy_p1 partition of part_xx_yy for values in ('xx');
create table part_xx_yy_defpart partition of part_xx_yy default;
create table part_default partition of list_parted default partition by range(b);
create table part_default_p1 partition of part_default for values from (20) to (30);
create table part_default_p2 partition of part_default for values from (30) to (40);
-- fail
insert into part_ee_ff1 values ('EE', 11);
insert into part_default_p2 values ('gg', 43);
-- fail (even the parent's, ie, part_ee_ff's partition constraint applies)
insert into part_ee_ff1 values ('cc', 1);
insert into part_default values ('gg', 43);
-- ok
insert into part_ee_ff1 values ('ff', 1);
insert into part_ee_ff2 values ('ff', 11);
insert into part_default_p1 values ('cd', 25);
insert into part_default_p2 values ('de', 35);
insert into list_parted values ('ab', 21);
insert into list_parted values ('xx', 1);
insert into list_parted values ('yy', 2);
select tableoid::regclass, * from list_parted;
-- Check tuple routing for partitioned tables
......@@ -154,8 +180,19 @@ insert into range_parted values ('b', 1);
insert into range_parted values ('b', 10);
-- fail (partition key (b+0) is null)
insert into range_parted values ('a');
select tableoid::regclass, * from range_parted;
-- Check default partition
create table part_def partition of range_parted default;
-- fail
insert into part_def values ('b', 10);
-- ok
insert into part_def values ('c', 10);
insert into range_parted values (null, null);
insert into range_parted values ('a', null);
insert into range_parted values (null, 19);
insert into range_parted values ('b', 20);
select tableoid::regclass, * from range_parted;
-- ok
insert into list_parted values (null, 1);
insert into list_parted (a) values ('aA');
......@@ -188,6 +225,18 @@ select tableoid::regclass::text, a, min(b) as min_b, max(b) as max_b from list_p
-- cleanup
drop table range_parted, list_parted;
-- test that a default partition added as the first partition accepts any value
-- including null
create table list_parted (a int) partition by list (a);
create table part_default partition of list_parted default;
\d+ part_default
insert into part_default values (null);
insert into part_default values (1);
insert into part_default values (-1);
select tableoid::regclass, a from list_parted;
-- cleanup
drop table list_parted;
-- more tests for certain multi-level partitioning scenarios
create table mlparted (a int, b int) partition by range (a, b);
create table mlparted1 (b int not null, a int not null) partition by range ((b+0));
......@@ -274,6 +323,24 @@ create function mlparted5abrtrig_func() returns trigger as $$ begin new.c = 'b';
create trigger mlparted5abrtrig before insert on mlparted5a for each row execute procedure mlparted5abrtrig_func();
insert into mlparted5 (a, b, c) values (1, 40, 'a');
drop table mlparted5;
alter table mlparted drop constraint check_b;
-- Check multi-level default partition
create table mlparted_def partition of mlparted default partition by range(a);
create table mlparted_def1 partition of mlparted_def for values from (40) to (50);
create table mlparted_def2 partition of mlparted_def for values from (50) to (60);
insert into mlparted values (40, 100);
insert into mlparted_def1 values (42, 100);
insert into mlparted_def2 values (54, 50);
-- fail
insert into mlparted values (70, 100);
insert into mlparted_def1 values (52, 50);
insert into mlparted_def2 values (34, 50);
-- ok
create table mlparted_defd partition of mlparted_def default;
insert into mlparted values (70, 100);
select tableoid::regclass, * from mlparted_def;
-- check that message shown after failure to find a partition shows the
-- appropriate key description (or none) in various situations
......
......@@ -156,3 +156,24 @@ end$$ language plpgsql;
select cachebug();
select cachebug();
-- Check that addition or removal of any partition is correctly dealt with by
-- default partition table when it is being used in prepared statement.
create table list_parted (a int) partition by list(a);
create table list_part_null partition of list_parted for values in (null);
create table list_part_1 partition of list_parted for values in (1);
create table list_part_def partition of list_parted default;
prepare pstmt_def_insert (int) as insert into list_part_def values($1);
-- should fail
execute pstmt_def_insert(null);
execute pstmt_def_insert(1);
create table list_part_2 partition of list_parted for values in (2);
execute pstmt_def_insert(2);
alter table list_parted detach partition list_part_null;
-- should be ok
execute pstmt_def_insert(null);
drop table list_part_1;
-- should be ok
execute pstmt_def_insert(1);
drop table list_parted, list_part_null;
deallocate pstmt_def_insert;
......@@ -125,5 +125,29 @@ update range_parted set b = b - 1 where b = 10;
-- ok
update range_parted set b = b + 1 where b = 10;
-- Creating default partition for range
create table part_def partition of range_parted default;
\d+ part_def
insert into range_parted values ('c', 9);
-- ok
update part_def set a = 'd' where a = 'c';
-- fail
update part_def set a = 'a' where a = 'd';
create table list_parted (
a text,
b int
) partition by list (a);
create table list_part1 partition of list_parted for values in ('a', 'b');
create table list_default partition of list_parted default;
insert into list_part1 values ('a', 1);
insert into list_default values ('d', 10);
-- fail
update list_default set a = 'a' where a = 'd';
-- ok
update list_default set a = 'x' where a = 'd';
-- cleanup
drop table range_parted;
drop table list_parted;
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment