Commit 1aba8e65 authored by Robert Haas's avatar Robert Haas

Add hash partitioning.

Hash partitioning is useful when you want to partition a growing data
set evenly.  This can be useful to keep table sizes reasonable, which
makes maintenance operations such as VACUUM faster, or to enable
partition-wise join.

At present, we still depend on constraint exclusion for partitioning
pruning, and the shape of the partition constraints for hash
partitioning is such that that doesn't work.  Work is underway to fix
that, which should both improve performance and make partitioning
pruning work with hash partitioning.

Amul Sul, reviewed and tested by Dilip Kumar, Ashutosh Bapat, Yugo
Nagata, Rajkumar Raghuwanshi, Jesper Pedersen, and by me.  A few
final tweaks also by me.

Discussion: http://postgr.es/m/CAAJ_b96fhpJAP=ALbETmeLk1Uni_GFZD938zgenhF49qgDTjaQ@mail.gmail.com
parent e7397f01
......@@ -2875,6 +2875,19 @@ VALUES ('Albany', NULL, NULL, 'NY');
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>Hash Partitioning</term>
<listitem>
<para>
The table is partitioned by specifying a modulus and a remainder for
each partition. Each partition will hold the rows for which the hash
value of the partition key divided by the specified modulus will
produce the specified remainder.
</para>
</listitem>
</varlistentry>
</variablelist>
If your application needs to use other forms of partitioning not listed
......@@ -2901,9 +2914,8 @@ VALUES ('Albany', NULL, NULL, 'NY');
All rows inserted into a partitioned table will be routed to one of the
<firstterm>partitions</firstterm> based on the value of the partition
key. Each partition has a subset of the data defined by its
<firstterm>partition bounds</firstterm>. Currently supported
partitioning methods include range and list, where each partition is
assigned a range of keys and a list of keys, respectively.
<firstterm>partition bounds</firstterm>. The currently supported
partitioning methods are range, list, and hash.
</para>
<para>
......@@ -3328,11 +3340,11 @@ ALTER TABLE measurement ATTACH PARTITION measurement_y2008m02
<listitem>
<para>
Declarative partitioning only supports list and range partitioning,
whereas table inheritance allows data to be divided in a manner of
the user's choosing. (Note, however, that if constraint exclusion is
unable to prune partitions effectively, query performance will be very
poor.)
Declarative partitioning only supports range, list and hash
partitioning, whereas table inheritance allows data to be divided in a
manner of the user's choosing. (Note, however, that if constraint
exclusion is unable to prune partitions effectively, query performance
will be very poor.)
</para>
</listitem>
......
......@@ -1431,6 +1431,13 @@ ALTER TABLE cities
ATTACH PARTITION cities_partdef DEFAULT;
</programlisting></para>
<para>
Attach a partition to hash partitioned table:
<programlisting>
ALTER TABLE orders
ATTACH PARTITION orders_p4 FOR VALUES WITH (MODULUS 4, REMAINDER 3);
</programlisting></para>
<para>
Detach a partition from partitioned table:
<programlisting>
......
This diff is collapsed.
This diff is collapsed.
......@@ -471,7 +471,7 @@ static void RangeVarCallbackForAlterRelation(const RangeVar *rv, Oid relid,
static bool is_partition_attr(Relation rel, AttrNumber attnum, bool *used_in_expr);
static PartitionSpec *transformPartitionSpec(Relation rel, PartitionSpec *partspec, char *strategy);
static void ComputePartitionAttrs(Relation rel, List *partParams, AttrNumber *partattrs,
List **partexprs, Oid *partopclass, Oid *partcollation);
List **partexprs, Oid *partopclass, Oid *partcollation, char strategy);
static void CreateInheritance(Relation child_rel, Relation parent_rel);
static void RemoveInheritance(Relation child_rel, Relation parent_rel);
static ObjectAddress ATExecAttachPartition(List **wqueue, Relation rel,
......@@ -894,7 +894,7 @@ DefineRelation(CreateStmt *stmt, char relkind, Oid ownerId,
ComputePartitionAttrs(rel, stmt->partspec->partParams,
partattrs, &partexprs, partopclass,
partcollation);
partcollation, strategy);
StorePartitionKey(rel, strategy, partnatts, partattrs, partexprs,
partopclass, partcollation);
......@@ -13337,7 +13337,9 @@ transformPartitionSpec(Relation rel, PartitionSpec *partspec, char *strategy)
newspec->location = partspec->location;
/* Parse partitioning strategy name */
if (pg_strcasecmp(partspec->strategy, "list") == 0)
if (pg_strcasecmp(partspec->strategy, "hash") == 0)
*strategy = PARTITION_STRATEGY_HASH;
else if (pg_strcasecmp(partspec->strategy, "list") == 0)
*strategy = PARTITION_STRATEGY_LIST;
else if (pg_strcasecmp(partspec->strategy, "range") == 0)
*strategy = PARTITION_STRATEGY_RANGE;
......@@ -13407,10 +13409,12 @@ transformPartitionSpec(Relation rel, PartitionSpec *partspec, char *strategy)
*/
static void
ComputePartitionAttrs(Relation rel, List *partParams, AttrNumber *partattrs,
List **partexprs, Oid *partopclass, Oid *partcollation)
List **partexprs, Oid *partopclass, Oid *partcollation,
char strategy)
{
int attn;
ListCell *lc;
Oid am_oid;
attn = 0;
foreach(lc, partParams)
......@@ -13570,25 +13574,41 @@ ComputePartitionAttrs(Relation rel, List *partParams, AttrNumber *partattrs,
partcollation[attn] = attcollation;
/*
* Identify a btree opclass to use. Currently, we use only btree
* operators, which seems enough for list and range partitioning.
* Identify the appropriate operator class. For list and range
* partitioning, we use a btree operator class; hash partitioning uses
* a hash operator class.
*/
if (strategy == PARTITION_STRATEGY_HASH)
am_oid = HASH_AM_OID;
else
am_oid = BTREE_AM_OID;
if (!pelem->opclass)
{
partopclass[attn] = GetDefaultOpClass(atttype, BTREE_AM_OID);
partopclass[attn] = GetDefaultOpClass(atttype, am_oid);
if (!OidIsValid(partopclass[attn]))
ereport(ERROR,
(errcode(ERRCODE_UNDEFINED_OBJECT),
errmsg("data type %s has no default btree operator class",
format_type_be(atttype)),
errhint("You must specify a btree operator class or define a default btree operator class for the data type.")));
{
if (strategy == PARTITION_STRATEGY_HASH)
ereport(ERROR,
(errcode(ERRCODE_UNDEFINED_OBJECT),
errmsg("data type %s has no default hash operator class",
format_type_be(atttype)),
errhint("You must specify a hash operator class or define a default hash operator class for the data type.")));
else
ereport(ERROR,
(errcode(ERRCODE_UNDEFINED_OBJECT),
errmsg("data type %s has no default btree operator class",
format_type_be(atttype)),
errhint("You must specify a btree operator class or define a default btree operator class for the data type.")));
}
}
else
partopclass[attn] = ResolveOpClass(pelem->opclass,
atttype,
"btree",
BTREE_AM_OID);
am_oid == HASH_AM_OID ? "hash" : "btree",
am_oid);
attn++;
}
......
......@@ -4461,6 +4461,8 @@ _copyPartitionBoundSpec(const PartitionBoundSpec *from)
COPY_SCALAR_FIELD(strategy);
COPY_SCALAR_FIELD(is_default);
COPY_SCALAR_FIELD(modulus);
COPY_SCALAR_FIELD(remainder);
COPY_NODE_FIELD(listdatums);
COPY_NODE_FIELD(lowerdatums);
COPY_NODE_FIELD(upperdatums);
......
......@@ -2848,6 +2848,8 @@ _equalPartitionBoundSpec(const PartitionBoundSpec *a, const PartitionBoundSpec *
{
COMPARE_SCALAR_FIELD(strategy);
COMPARE_SCALAR_FIELD(is_default);
COMPARE_SCALAR_FIELD(modulus);
COMPARE_SCALAR_FIELD(remainder);
COMPARE_NODE_FIELD(listdatums);
COMPARE_NODE_FIELD(lowerdatums);
COMPARE_NODE_FIELD(upperdatums);
......
......@@ -3578,6 +3578,8 @@ _outPartitionBoundSpec(StringInfo str, const PartitionBoundSpec *node)
WRITE_CHAR_FIELD(strategy);
WRITE_BOOL_FIELD(is_default);
WRITE_INT_FIELD(modulus);
WRITE_INT_FIELD(remainder);
WRITE_NODE_FIELD(listdatums);
WRITE_NODE_FIELD(lowerdatums);
WRITE_NODE_FIELD(upperdatums);
......
......@@ -2397,6 +2397,8 @@ _readPartitionBoundSpec(void)
READ_CHAR_FIELD(strategy);
READ_BOOL_FIELD(is_default);
READ_INT_FIELD(modulus);
READ_INT_FIELD(remainder);
READ_NODE_FIELD(listdatums);
READ_NODE_FIELD(lowerdatums);
READ_NODE_FIELD(upperdatums);
......
......@@ -1463,7 +1463,7 @@ have_partkey_equi_join(RelOptInfo *rel1, RelOptInfo *rel2, JoinType jointype,
continue;
/* Skip clauses which are not equality conditions. */
if (!rinfo->mergeopfamilies)
if (!rinfo->mergeopfamilies && !OidIsValid(rinfo->hashjoinoperator))
continue;
opexpr = (OpExpr *) rinfo->clause;
......@@ -1515,8 +1515,14 @@ have_partkey_equi_join(RelOptInfo *rel1, RelOptInfo *rel2, JoinType jointype,
* The clause allows partition-wise join if only it uses the same
* operator family as that specified by the partition key.
*/
if (!list_member_oid(rinfo->mergeopfamilies,
part_scheme->partopfamily[ipk1]))
if (rel1->part_scheme->strategy == PARTITION_STRATEGY_HASH)
{
if (!op_in_opfamily(rinfo->hashjoinoperator,
part_scheme->partopfamily[ipk1]))
continue;
}
else if (!list_member_oid(rinfo->mergeopfamilies,
part_scheme->partopfamily[ipk1]))
continue;
/* Mark the partition key as having an equi-join clause. */
......
......@@ -579,7 +579,8 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <list> part_params
%type <partboundspec> PartitionBoundSpec
%type <node> partbound_datum PartitionRangeDatum
%type <list> partbound_datum_list range_datum_list
%type <list> hash_partbound partbound_datum_list range_datum_list
%type <defelt> hash_partbound_elem
/*
* Non-keyword token types. These are hard-wired into the "flex" lexer.
......@@ -2638,8 +2639,61 @@ alter_identity_column_option:
;
PartitionBoundSpec:
/* a HASH partition*/
FOR VALUES WITH '(' hash_partbound ')'
{
ListCell *lc;
PartitionBoundSpec *n = makeNode(PartitionBoundSpec);
n->strategy = PARTITION_STRATEGY_HASH;
n->modulus = n->remainder = -1;
foreach (lc, $5)
{
DefElem *opt = lfirst_node(DefElem, lc);
if (strcmp(opt->defname, "modulus") == 0)
{
if (n->modulus != -1)
ereport(ERROR,
(errcode(ERRCODE_DUPLICATE_OBJECT),
errmsg("modulus for hash partition provided more than once"),
parser_errposition(opt->location)));
n->modulus = defGetInt32(opt);
}
else if (strcmp(opt->defname, "remainder") == 0)
{
if (n->remainder != -1)
ereport(ERROR,
(errcode(ERRCODE_DUPLICATE_OBJECT),
errmsg("remainder for hash partition provided more than once"),
parser_errposition(opt->location)));
n->remainder = defGetInt32(opt);
}
else
ereport(ERROR,
(errcode(ERRCODE_SYNTAX_ERROR),
errmsg("unrecognized hash partition bound specification \"%s\"",
opt->defname),
parser_errposition(opt->location)));
}
if (n->modulus == -1)
ereport(ERROR,
(errcode(ERRCODE_SYNTAX_ERROR),
errmsg("modulus for hash partition must be specified")));
if (n->remainder == -1)
ereport(ERROR,
(errcode(ERRCODE_SYNTAX_ERROR),
errmsg("remainder for hash partition must be specified")));
n->location = @3;
$$ = n;
}
/* a LIST partition */
FOR VALUES IN_P '(' partbound_datum_list ')'
| FOR VALUES IN_P '(' partbound_datum_list ')'
{
PartitionBoundSpec *n = makeNode(PartitionBoundSpec);
......@@ -2677,6 +2731,24 @@ PartitionBoundSpec:
}
;
hash_partbound_elem:
NonReservedWord Iconst
{
$$ = makeDefElem($1, (Node *)makeInteger($2), @1);
}
;
hash_partbound:
hash_partbound_elem
{
$$ = list_make1($1);
}
| hash_partbound ',' hash_partbound_elem
{
$$ = lappend($1, $3);
}
;
partbound_datum:
Sconst { $$ = makeStringConst($1, @1); }
| NumericOnly { $$ = makeAConst($1, @1); }
......
......@@ -3310,6 +3310,11 @@ transformPartitionBound(ParseState *pstate, Relation parent,
if (spec->is_default)
{
if (strategy == PARTITION_STRATEGY_HASH)
ereport(ERROR,
(errcode(ERRCODE_INVALID_TABLE_DEFINITION),
errmsg("a hash-partitioned table may not have a default partition")));
/*
* In case of the default partition, parser had no way to identify the
* partition strategy. Assign the parent's strategy to the default
......@@ -3320,7 +3325,27 @@ transformPartitionBound(ParseState *pstate, Relation parent,
return result_spec;
}
if (strategy == PARTITION_STRATEGY_LIST)
if (strategy == PARTITION_STRATEGY_HASH)
{
if (spec->strategy != PARTITION_STRATEGY_HASH)
ereport(ERROR,
(errcode(ERRCODE_INVALID_TABLE_DEFINITION),
errmsg("invalid bound specification for a hash partition"),
parser_errposition(pstate, exprLocation((Node *) spec))));
if (spec->modulus <= 0)
ereport(ERROR,
(errcode(ERRCODE_INVALID_TABLE_DEFINITION),
errmsg("modulus for hash partition must be a positive integer")));
Assert(spec->remainder >= 0);
if (spec->remainder >= spec->modulus)
ereport(ERROR,
(errcode(ERRCODE_INVALID_TABLE_DEFINITION),
errmsg("remainder for hash partition must be less than modulus")));
}
else if (strategy == PARTITION_STRATEGY_LIST)
{
ListCell *cell;
char *colname;
......@@ -3485,7 +3510,7 @@ transformPartitionBound(ParseState *pstate, Relation parent,
static void
validateInfiniteBounds(ParseState *pstate, List *blist)
{
ListCell *lc;
ListCell *lc;
PartitionRangeDatumKind kind = PARTITION_RANGE_DATUM_VALUE;
foreach(lc, blist)
......
......@@ -1551,7 +1551,7 @@ pg_get_statisticsobj_worker(Oid statextid, bool missing_ok)
*
* Returns the partition key specification, ie, the following:
*
* PARTITION BY { RANGE | LIST } (column opt_collation opt_opclass [, ...])
* PARTITION BY { RANGE | LIST | HASH } (column opt_collation opt_opclass [, ...])
*/
Datum
pg_get_partkeydef(PG_FUNCTION_ARGS)
......@@ -1655,6 +1655,10 @@ pg_get_partkeydef_worker(Oid relid, int prettyFlags,
switch (form->partstrat)
{
case PARTITION_STRATEGY_HASH:
if (!attrsOnly)
appendStringInfo(&buf, "HASH");
break;
case PARTITION_STRATEGY_LIST:
if (!attrsOnly)
appendStringInfoString(&buf, "LIST");
......@@ -8711,6 +8715,15 @@ get_rule_expr(Node *node, deparse_context *context,
switch (spec->strategy)
{
case PARTITION_STRATEGY_HASH:
Assert(spec->modulus > 0 && spec->remainder >= 0);
Assert(spec->modulus > spec->remainder);
appendStringInfoString(buf, "FOR VALUES");
appendStringInfo(buf, " WITH (modulus %d, remainder %d)",
spec->modulus, spec->remainder);
break;
case PARTITION_STRATEGY_LIST:
Assert(spec->listdatums != NIL);
......
......@@ -30,6 +30,7 @@
#include <fcntl.h>
#include <unistd.h>
#include "access/hash.h"
#include "access/htup_details.h"
#include "access/multixact.h"
#include "access/nbtree.h"
......@@ -833,6 +834,7 @@ RelationBuildPartitionKey(Relation relation)
Datum datum;
MemoryContext partkeycxt,
oldcxt;
int16 procnum;
tuple = SearchSysCache1(PARTRELID,
ObjectIdGetDatum(RelationGetRelid(relation)));
......@@ -912,6 +914,10 @@ RelationBuildPartitionKey(Relation relation)
key->parttypalign = (char *) palloc0(key->partnatts * sizeof(char));
key->parttypcoll = (Oid *) palloc0(key->partnatts * sizeof(Oid));
/* For the hash partitioning, an extended hash function will be used. */
procnum = (key->strategy == PARTITION_STRATEGY_HASH) ?
HASHEXTENDED_PROC : BTORDER_PROC;
/* Copy partattrs and fill other per-attribute info */
memcpy(key->partattrs, attrs, key->partnatts * sizeof(int16));
partexprs_item = list_head(key->partexprs);
......@@ -932,18 +938,20 @@ RelationBuildPartitionKey(Relation relation)
key->partopfamily[i] = opclassform->opcfamily;
key->partopcintype[i] = opclassform->opcintype;
/*
* A btree support function covers the cases of list and range methods
* currently supported.
*/
/* Get a support function for the specified opfamily and datatypes */
funcid = get_opfamily_proc(opclassform->opcfamily,
opclassform->opcintype,
opclassform->opcintype,
BTORDER_PROC);
if (!OidIsValid(funcid)) /* should not happen */
elog(ERROR, "missing support function %d(%u,%u) in opfamily %u",
BTORDER_PROC, opclassform->opcintype, opclassform->opcintype,
opclassform->opcfamily);
procnum);
if (!OidIsValid(funcid))
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
errmsg("operator class \"%s\" of access method %s is missing support function %d for data type \"%s\"",
NameStr(opclassform->opcname),
(key->strategy == PARTITION_STRATEGY_HASH) ?
"hash" : "btree",
procnum,
format_type_be(opclassform->opcintype))));
fmgr_info(funcid, &key->partsupfunc[i]);
......
......@@ -2055,7 +2055,7 @@ psql_completion(const char *text, int start, int end)
else if (TailMatches3("ATTACH", "PARTITION", MatchAny))
COMPLETE_WITH_LIST2("FOR VALUES", "DEFAULT");
else if (TailMatches2("FOR", "VALUES"))
COMPLETE_WITH_LIST2("FROM (", "IN (");
COMPLETE_WITH_LIST3("FROM (", "IN (", "WITH (");
/*
* If we have ALTER TABLE <foo> DETACH PARTITION, provide a list of
......
......@@ -53,6 +53,6 @@
*/
/* yyyymmddN */
#define CATALOG_VERSION_NO 201711091
#define CATALOG_VERSION_NO 201711092
#endif
......@@ -19,6 +19,9 @@
#include "parser/parse_node.h"
#include "utils/rel.h"
/* Seed for the extended hash function */
#define HASH_PARTITION_SEED UINT64CONST(0x7A5B22367996DCFD)
/*
* PartitionBoundInfo encapsulates a set of partition bounds. It is usually
* associated with partitioned tables as part of its partition descriptor.
......
......@@ -5522,6 +5522,10 @@ DESCR("list files in the log directory");
DATA(insert OID = 3354 ( pg_ls_waldir PGNSP PGUID 12 10 20 0 0 f f f f t t v s 0 0 2249 "" "{25,20,1184}" "{o,o,o}" "{name,size,modification}" _null_ _null_ pg_ls_waldir _null_ _null_ _null_ ));
DESCR("list of files in the WAL directory");
/* hash partitioning constraint function */
DATA(insert OID = 5028 ( satisfies_hash_partition PGNSP PGUID 12 1 0 2276 0 f f f f f f i s 4 0 16 "26 23 23 2276" _null_ _null_ _null_ _null_ _null_ satisfies_hash_partition _null_ _null_ _null_ ));
DESCR("hash partition CHECK constraint");
/*
* Symbolic values for provolatile column: these indicate whether the result
* of a function is dependent *only* on the values of its explicit arguments,
......
......@@ -777,12 +777,14 @@ typedef struct PartitionElem
typedef struct PartitionSpec
{
NodeTag type;
char *strategy; /* partitioning strategy ('list' or 'range') */
char *strategy; /* partitioning strategy ('hash', 'list' or
* 'range') */
List *partParams; /* List of PartitionElems */
int location; /* token location, or -1 if unknown */
} PartitionSpec;
/* Internal codes for partitioning strategies */
#define PARTITION_STRATEGY_HASH 'h'
#define PARTITION_STRATEGY_LIST 'l'
#define PARTITION_STRATEGY_RANGE 'r'
......@@ -799,6 +801,10 @@ typedef struct PartitionBoundSpec
char strategy; /* see PARTITION_STRATEGY codes above */
bool is_default; /* is it a default partition bound? */
/* Partitioning info for HASH strategy: */
int modulus;
int remainder;
/* Partitioning info for LIST strategy: */
List *listdatums; /* List of Consts (or A_Consts in raw tree) */
......
......@@ -3399,6 +3399,7 @@ 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"
DROP TABLE fail_part;
-- 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;
......@@ -3596,6 +3597,59 @@ CREATE TABLE quuux1 PARTITION OF quuux FOR VALUES IN (1);
CREATE TABLE quuux2 PARTITION OF quuux FOR VALUES IN (2);
INFO: updated partition constraint for default partition "quuux_default1" is implied by existing constraints
DROP TABLE quuux;
-- check validation when attaching hash partitions
-- The default hash functions as they exist today aren't portable; they can
-- return different results on different machines. Depending upon how the
-- values are hashed, the row may map to different partitions, which result in
-- regression failure. To avoid this, let's create a non-default hash function
-- that just returns the input value unchanged.
CREATE OR REPLACE FUNCTION dummy_hashint4(a int4, seed int8) RETURNS int8 AS
$$ BEGIN RETURN (a + 1 + seed); END; $$ LANGUAGE 'plpgsql' IMMUTABLE;
CREATE OPERATOR CLASS custom_opclass FOR TYPE int4 USING HASH AS
OPERATOR 1 = , FUNCTION 2 dummy_hashint4(int4, int8);
-- check that the new partition won't overlap with an existing partition
CREATE TABLE hash_parted (
a int,
b int
) PARTITION BY HASH (a custom_opclass);
CREATE TABLE hpart_1 PARTITION OF hash_parted FOR VALUES WITH (MODULUS 4, REMAINDER 0);
CREATE TABLE fail_part (LIKE hpart_1);
ALTER TABLE hash_parted ATTACH PARTITION fail_part FOR VALUES WITH (MODULUS 8, REMAINDER 4);
ERROR: partition "fail_part" would overlap partition "hpart_1"
ALTER TABLE hash_parted ATTACH PARTITION fail_part FOR VALUES WITH (MODULUS 8, REMAINDER 0);
ERROR: partition "fail_part" would overlap partition "hpart_1"
DROP TABLE fail_part;
-- check validation when attaching hash partitions
-- check that violating rows are correctly reported
CREATE TABLE hpart_2 (LIKE hash_parted);
INSERT INTO hpart_2 VALUES (3, 0);
ALTER TABLE hash_parted ATTACH PARTITION hpart_2 FOR VALUES WITH (MODULUS 4, REMAINDER 1);
ERROR: partition constraint is violated by some row
-- should be ok after deleting the bad row
DELETE FROM hpart_2;
ALTER TABLE hash_parted ATTACH PARTITION hpart_2 FOR VALUES WITH (MODULUS 4, REMAINDER 1);
-- check that leaf partitions are scanned when attaching a partitioned
-- table
CREATE TABLE hpart_5 (
LIKE hash_parted
) PARTITION BY LIST (b);
-- check that violating rows are correctly reported
CREATE TABLE hpart_5_a PARTITION OF hpart_5 FOR VALUES IN ('1', '2', '3');
INSERT INTO hpart_5_a (a, b) VALUES (7, 1);
ALTER TABLE hash_parted ATTACH PARTITION hpart_5 FOR VALUES WITH (MODULUS 4, REMAINDER 2);
ERROR: partition constraint is violated by some row
-- should be ok after deleting the bad row
DELETE FROM hpart_5_a;
ALTER TABLE hash_parted ATTACH PARTITION hpart_5 FOR VALUES WITH (MODULUS 4, REMAINDER 2);
-- check that the table being attach is with valid modulus and remainder value
CREATE TABLE fail_part(LIKE hash_parted);
ALTER TABLE hash_parted ATTACH PARTITION fail_part FOR VALUES WITH (MODULUS 0, REMAINDER 1);
ERROR: modulus for hash partition must be a positive integer
ALTER TABLE hash_parted ATTACH PARTITION fail_part FOR VALUES WITH (MODULUS 8, REMAINDER 8);
ERROR: remainder for hash partition must be less than modulus
ALTER TABLE hash_parted ATTACH PARTITION fail_part FOR VALUES WITH (MODULUS 3, REMAINDER 2);
ERROR: every hash partition modulus must be a factor of the next larger modulus
DROP TABLE fail_part;
--
-- DETACH PARTITION
--
......@@ -3607,12 +3661,17 @@ DROP TABLE regular_table;
-- check that the partition being detached exists at all
ALTER TABLE list_parted2 DETACH PARTITION part_4;
ERROR: relation "part_4" does not exist
ALTER TABLE hash_parted DETACH PARTITION hpart_4;
ERROR: relation "hpart_4" does not exist
-- check that the partition being detached is actually a partition of the parent
CREATE TABLE not_a_part (a int);
ALTER TABLE list_parted2 DETACH PARTITION not_a_part;
ERROR: relation "not_a_part" is not a partition of relation "list_parted2"
ALTER TABLE list_parted2 DETACH PARTITION part_1;
ERROR: relation "part_1" is not a partition of relation "list_parted2"
ALTER TABLE hash_parted DETACH PARTITION not_a_part;
ERROR: relation "not_a_part" is not a partition of relation "hash_parted"
DROP TABLE not_a_part;
-- check that, after being detached, attinhcount/coninhcount is dropped to 0 and
-- attislocal/conislocal is set to true
ALTER TABLE list_parted2 DETACH PARTITION part_3_4;
......@@ -3716,6 +3775,9 @@ SELECT * FROM list_parted;
-- cleanup
DROP TABLE list_parted, list_parted2, range_parted;
DROP TABLE fail_def_part;
DROP TABLE hash_parted;
DROP OPERATOR CLASS custom_opclass USING HASH;
DROP FUNCTION dummy_hashint4(a int4, seed int8);
-- 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);
......
......@@ -340,11 +340,11 @@ CREATE TABLE partitioned (
) PARTITION BY RANGE (const_func());
ERROR: cannot use constant expression as partition key
DROP FUNCTION const_func();
-- only accept "list" and "range" as partitioning strategy
-- only accept valid partitioning strategy
CREATE TABLE partitioned (
a int
) PARTITION BY HASH (a);
ERROR: unrecognized partitioning strategy "hash"
a int
) PARTITION BY MAGIC (a);
ERROR: unrecognized partitioning strategy "magic"
-- specified column must be present in the table
CREATE TABLE partitioned (
a int
......@@ -467,6 +467,11 @@ 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...
^
-- trying to specify modulus and remainder for list partitioned table
CREATE TABLE fail_part PARTITION OF list_parted FOR VALUES WITH (MODULUS 10, REMAINDER 1);
ERROR: invalid bound specification for a list partition
LINE 1: ...BLE fail_part PARTITION OF list_parted FOR VALUES WITH (MODU...
^
-- 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;
......@@ -509,6 +514,11 @@ CREATE TABLE fail_part PARTITION OF range_parted FOR VALUES IN ('a');
ERROR: invalid bound specification for a range partition
LINE 1: ...BLE fail_part PARTITION OF range_parted FOR VALUES IN ('a');
^
-- trying to specify modulus and remainder for range partitioned table
CREATE TABLE fail_part PARTITION OF range_parted FOR VALUES WITH (MODULUS 10, REMAINDER 1);
ERROR: invalid bound specification for a range partition
LINE 1: ...LE fail_part PARTITION OF range_parted FOR VALUES WITH (MODU...
^
-- each of start and end bounds must have same number of values as the
-- length of the partition key
CREATE TABLE fail_part PARTITION OF range_parted FOR VALUES FROM ('a', 1) TO ('z');
......@@ -518,6 +528,37 @@ ERROR: TO must specify exactly one value per partitioning column
-- cannot specify null values in range bounds
CREATE TABLE fail_part PARTITION OF range_parted FOR VALUES FROM (null) TO (maxvalue);
ERROR: cannot specify NULL in range bound
-- trying to specify modulus and remainder for range partitioned table
CREATE TABLE fail_part PARTITION OF range_parted FOR VALUES WITH (MODULUS 10, REMAINDER 1);
ERROR: invalid bound specification for a range partition
LINE 1: ...LE fail_part PARTITION OF range_parted FOR VALUES WITH (MODU...
^
-- check partition bound syntax for the hash partition
CREATE TABLE hash_parted (
a int
) PARTITION BY HASH (a);
CREATE TABLE hpart_1 PARTITION OF hash_parted FOR VALUES WITH (MODULUS 10, REMAINDER 0);
CREATE TABLE hpart_2 PARTITION OF hash_parted FOR VALUES WITH (MODULUS 50, REMAINDER 1);
CREATE TABLE hpart_3 PARTITION OF hash_parted FOR VALUES WITH (MODULUS 200, REMAINDER 2);
-- modulus 25 is factor of modulus of 50 but 10 is not factor of 25.
CREATE TABLE fail_part PARTITION OF hash_parted FOR VALUES WITH (MODULUS 25, REMAINDER 3);
ERROR: every hash partition modulus must be a factor of the next larger modulus
-- previous modulus 50 is factor of 150 but this modulus is not factor of next modulus 200.
CREATE TABLE fail_part PARTITION OF hash_parted FOR VALUES WITH (MODULUS 150, REMAINDER 3);
ERROR: every hash partition modulus must be a factor of the next larger modulus
-- trying to specify range for the hash partitioned table
CREATE TABLE fail_part PARTITION OF hash_parted FOR VALUES FROM ('a', 1) TO ('z');
ERROR: invalid bound specification for a hash partition
LINE 1: ...BLE fail_part PARTITION OF hash_parted FOR VALUES FROM ('a',...
^
-- trying to specify list value for the hash partitioned table
CREATE TABLE fail_part PARTITION OF hash_parted FOR VALUES IN (1000);
ERROR: invalid bound specification for a hash partition
LINE 1: ...BLE fail_part PARTITION OF hash_parted FOR VALUES IN (1000);
^
-- trying to create default partition for the hash partitioned table
CREATE TABLE fail_default_part PARTITION OF hash_parted DEFAULT;
ERROR: a hash-partitioned table may not have a default partition
-- check if compatible with the specified parent
-- cannot create as partition of a non-partitioned table
CREATE TABLE unparted (
......@@ -525,6 +566,8 @@ CREATE TABLE unparted (
);
CREATE TABLE fail_part PARTITION OF unparted FOR VALUES IN ('a');
ERROR: "unparted" is not partitioned
CREATE TABLE fail_part PARTITION OF unparted FOR VALUES WITH (MODULUS 2, REMAINDER 1);
ERROR: "unparted" is not partitioned
DROP TABLE unparted;
-- cannot create a permanent rel as partition of a temp rel
CREATE TEMP TABLE temp_parted (
......@@ -623,6 +666,23 @@ CREATE TABLE range3_default PARTITION OF range_parted3 DEFAULT;
-- more specific ranges
CREATE TABLE fail_part PARTITION OF range_parted3 FOR VALUES FROM (1, minvalue) TO (1, maxvalue);
ERROR: partition "fail_part" would overlap partition "part10"
-- check for partition bound overlap and other invalid specifications for the hash partition
CREATE TABLE hash_parted2 (
a varchar
) PARTITION BY HASH (a);
CREATE TABLE h2part_1 PARTITION OF hash_parted2 FOR VALUES WITH (MODULUS 4, REMAINDER 2);
CREATE TABLE h2part_2 PARTITION OF hash_parted2 FOR VALUES WITH (MODULUS 8, REMAINDER 0);
CREATE TABLE h2part_3 PARTITION OF hash_parted2 FOR VALUES WITH (MODULUS 8, REMAINDER 4);
CREATE TABLE h2part_4 PARTITION OF hash_parted2 FOR VALUES WITH (MODULUS 8, REMAINDER 5);
-- overlap with part_4
CREATE TABLE fail_part PARTITION OF hash_parted2 FOR VALUES WITH (MODULUS 2, REMAINDER 1);
ERROR: partition "fail_part" would overlap partition "h2part_4"
-- modulus must be greater than zero
CREATE TABLE fail_part PARTITION OF hash_parted2 FOR VALUES WITH (MODULUS 0, REMAINDER 1);
ERROR: modulus for hash partition must be a positive integer
-- remainder must be greater than or equal to zero and less than modulus
CREATE TABLE fail_part PARTITION OF hash_parted2 FOR VALUES WITH (MODULUS 8, REMAINDER 8);
ERROR: remainder for hash partition must be less than modulus
-- check schema propagation from parent
CREATE TABLE parted (
a text,
......@@ -721,6 +781,14 @@ Check constraints:
"check_a" CHECK (length(a) > 0)
Number of partitions: 3 (Use \d+ to list them.)
\d hash_parted
Table "public.hash_parted"
Column | Type | Collation | Nullable | Default
--------+---------+-----------+----------+---------
a | integer | | |
Partition key: HASH (a)
Number of partitions: 3 (Use \d+ to list them.)
-- check that we get the expected partition constraints
CREATE TABLE range_parted4 (a int, b int, c int) PARTITION BY RANGE (abs(a), abs(b), c);
CREATE TABLE unbounded_range_part PARTITION OF range_parted4 FOR VALUES FROM (MINVALUE, MINVALUE, MINVALUE) TO (MAXVALUE, MAXVALUE, MAXVALUE);
......@@ -771,6 +839,8 @@ Partition constraint: ((abs(a) IS NOT NULL) AND (abs(b) IS NOT NULL) AND (c IS N
DROP TABLE range_parted4;
-- cleanup
DROP TABLE parted, list_parted, range_parted, list_parted2, range_parted2, range_parted3;
DROP TABLE hash_parted;
DROP TABLE hash_parted2;
-- comments on partitioned tables columns
CREATE TABLE parted_col_comment (a int, b text) PARTITION BY LIST (a);
COMMENT ON TABLE parted_col_comment IS 'Am partitioned table';
......
......@@ -382,8 +382,54 @@ select tableoid::regclass::text, a, min(b) as min_b, max(b) as max_b from list_p
part_null | | 1 | 1
(9 rows)
-- direct partition inserts should check hash partition bound constraint
-- create custom operator class and hash function, for the same reason
-- explained in alter_table.sql
create or replace function dummy_hashint4(a int4, seed int8) returns int8 as
$$ begin return (a + seed); end; $$ language 'plpgsql' immutable;
create operator class custom_opclass for type int4 using hash as
operator 1 = , function 2 dummy_hashint4(int4, int8);
create table hash_parted (
a int
) partition by hash (a custom_opclass);
create table hpart0 partition of hash_parted for values with (modulus 4, remainder 0);
create table hpart1 partition of hash_parted for values with (modulus 4, remainder 1);
create table hpart2 partition of hash_parted for values with (modulus 4, remainder 2);
create table hpart3 partition of hash_parted for values with (modulus 4, remainder 3);
insert into hash_parted values(generate_series(1,10));
-- direct insert of values divisible by 4 - ok;
insert into hpart0 values(12),(16);
-- fail;
insert into hpart0 values(11);
ERROR: new row for relation "hpart0" violates partition constraint
DETAIL: Failing row contains (11).
-- 11 % 4 -> 3 remainder i.e. valid data for hpart3 partition
insert into hpart3 values(11);
-- view data
select tableoid::regclass as part, a, a%4 as "remainder = a % 4"
from hash_parted order by part;
part | a | remainder = a % 4
--------+----+-------------------
hpart0 | 4 | 0
hpart0 | 8 | 0
hpart0 | 12 | 0
hpart0 | 16 | 0
hpart1 | 1 | 1
hpart1 | 5 | 1
hpart1 | 9 | 1
hpart2 | 2 | 2
hpart2 | 6 | 2
hpart2 | 10 | 2
hpart3 | 3 | 3
hpart3 | 7 | 3
hpart3 | 11 | 3
(13 rows)
-- cleanup
drop table range_parted, list_parted;
drop table hash_parted;
drop operator class custom_opclass using hash;
drop function dummy_hashint4(a int4, seed int8);
-- 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);
......
......@@ -1256,6 +1256,87 @@ SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1
One-Time Filter: false
(14 rows)
--
-- tests for hash partitioned tables.
--
CREATE TABLE pht1 (a int, b int, c text) PARTITION BY HASH(c);
CREATE TABLE pht1_p1 PARTITION OF pht1 FOR VALUES WITH (MODULUS 3, REMAINDER 0);
CREATE TABLE pht1_p2 PARTITION OF pht1 FOR VALUES WITH (MODULUS 3, REMAINDER 1);
CREATE TABLE pht1_p3 PARTITION OF pht1 FOR VALUES WITH (MODULUS 3, REMAINDER 2);
INSERT INTO pht1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
ANALYZE pht1;
CREATE TABLE pht2 (a int, b int, c text) PARTITION BY HASH(c);
CREATE TABLE pht2_p1 PARTITION OF pht2 FOR VALUES WITH (MODULUS 3, REMAINDER 0);
CREATE TABLE pht2_p2 PARTITION OF pht2 FOR VALUES WITH (MODULUS 3, REMAINDER 1);
CREATE TABLE pht2_p3 PARTITION OF pht2 FOR VALUES WITH (MODULUS 3, REMAINDER 2);
INSERT INTO pht2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
ANALYZE pht2;
--
-- hash partitioned by expression
--
CREATE TABLE pht1_e (a int, b int, c text) PARTITION BY HASH(ltrim(c, 'A'));
CREATE TABLE pht1_e_p1 PARTITION OF pht1_e FOR VALUES WITH (MODULUS 3, REMAINDER 0);
CREATE TABLE pht1_e_p2 PARTITION OF pht1_e FOR VALUES WITH (MODULUS 3, REMAINDER 1);
CREATE TABLE pht1_e_p3 PARTITION OF pht1_e FOR VALUES WITH (MODULUS 3, REMAINDER 2);
INSERT INTO pht1_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
ANALYZE pht1_e;
-- test partition matching with N-way join
EXPLAIN (COSTS OFF)
SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM pht1 t1, pht2 t2, pht1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
QUERY PLAN
--------------------------------------------------------------------------------------
Sort
Sort Key: t1.c, t3.c
-> HashAggregate
Group Key: t1.c, t2.c, t3.c
-> Result
-> Append
-> Hash Join
Hash Cond: (t1.c = t2.c)
-> Seq Scan on pht1_p1 t1
-> Hash
-> Hash Join
Hash Cond: (t2.c = ltrim(t3.c, 'A'::text))
-> Seq Scan on pht2_p1 t2
-> Hash
-> Seq Scan on pht1_e_p1 t3
-> Hash Join
Hash Cond: (t1_1.c = t2_1.c)
-> Seq Scan on pht1_p2 t1_1
-> Hash
-> Hash Join
Hash Cond: (t2_1.c = ltrim(t3_1.c, 'A'::text))
-> Seq Scan on pht2_p2 t2_1
-> Hash
-> Seq Scan on pht1_e_p2 t3_1
-> Hash Join
Hash Cond: (t1_2.c = t2_2.c)
-> Seq Scan on pht1_p3 t1_2
-> Hash
-> Hash Join
Hash Cond: (t2_2.c = ltrim(t3_2.c, 'A'::text))
-> Seq Scan on pht2_p3 t2_2
-> Hash
-> Seq Scan on pht1_e_p3 t3_2
(33 rows)
SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM pht1 t1, pht2 t2, pht1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
avg | avg | avg | c | c | c
----------------------+----------------------+-----------------------+------+------+-------
24.0000000000000000 | 24.0000000000000000 | 48.0000000000000000 | 0000 | 0000 | A0000
74.0000000000000000 | 75.0000000000000000 | 148.0000000000000000 | 0001 | 0001 | A0001
124.0000000000000000 | 124.5000000000000000 | 248.0000000000000000 | 0002 | 0002 | A0002
174.0000000000000000 | 174.0000000000000000 | 348.0000000000000000 | 0003 | 0003 | A0003
224.0000000000000000 | 225.0000000000000000 | 448.0000000000000000 | 0004 | 0004 | A0004
274.0000000000000000 | 274.5000000000000000 | 548.0000000000000000 | 0005 | 0005 | A0005
324.0000000000000000 | 324.0000000000000000 | 648.0000000000000000 | 0006 | 0006 | A0006
374.0000000000000000 | 375.0000000000000000 | 748.0000000000000000 | 0007 | 0007 | A0007
424.0000000000000000 | 424.5000000000000000 | 848.0000000000000000 | 0008 | 0008 | A0008
474.0000000000000000 | 474.0000000000000000 | 948.0000000000000000 | 0009 | 0009 | A0009
524.0000000000000000 | 525.0000000000000000 | 1048.0000000000000000 | 0010 | 0010 | A0010
574.0000000000000000 | 574.5000000000000000 | 1148.0000000000000000 | 0011 | 0011 | A0011
(12 rows)
--
-- multiple levels of partitioning
--
......
......@@ -250,6 +250,35 @@ 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';
-- create custom operator class and hash function, for the same reason
-- explained in alter_table.sql
create or replace function dummy_hashint4(a int4, seed int8) returns int8 as
$$ begin return (a + seed); end; $$ language 'plpgsql' immutable;
create operator class custom_opclass for type int4 using hash as
operator 1 = , function 2 dummy_hashint4(int4, int8);
create table hash_parted (
a int,
b int
) partition by hash (a custom_opclass, b custom_opclass);
create table hpart1 partition of hash_parted for values with (modulus 2, remainder 1);
create table hpart2 partition of hash_parted for values with (modulus 4, remainder 2);
create table hpart3 partition of hash_parted for values with (modulus 8, remainder 0);
create table hpart4 partition of hash_parted for values with (modulus 8, remainder 4);
insert into hpart1 values (1, 1);
insert into hpart2 values (2, 5);
insert into hpart4 values (3, 4);
-- fail
update hpart1 set a = 3, b=4 where a = 1;
ERROR: new row for relation "hpart1" violates partition constraint
DETAIL: Failing row contains (3, 4).
update hash_parted set b = b - 1 where b = 1;
ERROR: new row for relation "hpart1" violates partition constraint
DETAIL: Failing row contains (1, 0).
-- ok
update hash_parted set b = b + 8 where b = 1;
-- cleanup
drop table range_parted;
drop table list_parted;
drop table hash_parted;
drop operator class custom_opclass using hash;
drop function dummy_hashint4(a int4, seed int8);
......@@ -2139,6 +2139,7 @@ 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);
DROP TABLE fail_part;
-- 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;
......@@ -2332,6 +2333,62 @@ CREATE TABLE quuux1 PARTITION OF quuux FOR VALUES IN (1);
CREATE TABLE quuux2 PARTITION OF quuux FOR VALUES IN (2);
DROP TABLE quuux;
-- check validation when attaching hash partitions
-- The default hash functions as they exist today aren't portable; they can
-- return different results on different machines. Depending upon how the
-- values are hashed, the row may map to different partitions, which result in
-- regression failure. To avoid this, let's create a non-default hash function
-- that just returns the input value unchanged.
CREATE OR REPLACE FUNCTION dummy_hashint4(a int4, seed int8) RETURNS int8 AS
$$ BEGIN RETURN (a + 1 + seed); END; $$ LANGUAGE 'plpgsql' IMMUTABLE;
CREATE OPERATOR CLASS custom_opclass FOR TYPE int4 USING HASH AS
OPERATOR 1 = , FUNCTION 2 dummy_hashint4(int4, int8);
-- check that the new partition won't overlap with an existing partition
CREATE TABLE hash_parted (
a int,
b int
) PARTITION BY HASH (a custom_opclass);
CREATE TABLE hpart_1 PARTITION OF hash_parted FOR VALUES WITH (MODULUS 4, REMAINDER 0);
CREATE TABLE fail_part (LIKE hpart_1);
ALTER TABLE hash_parted ATTACH PARTITION fail_part FOR VALUES WITH (MODULUS 8, REMAINDER 4);
ALTER TABLE hash_parted ATTACH PARTITION fail_part FOR VALUES WITH (MODULUS 8, REMAINDER 0);
DROP TABLE fail_part;
-- check validation when attaching hash partitions
-- check that violating rows are correctly reported
CREATE TABLE hpart_2 (LIKE hash_parted);
INSERT INTO hpart_2 VALUES (3, 0);
ALTER TABLE hash_parted ATTACH PARTITION hpart_2 FOR VALUES WITH (MODULUS 4, REMAINDER 1);
-- should be ok after deleting the bad row
DELETE FROM hpart_2;
ALTER TABLE hash_parted ATTACH PARTITION hpart_2 FOR VALUES WITH (MODULUS 4, REMAINDER 1);
-- check that leaf partitions are scanned when attaching a partitioned
-- table
CREATE TABLE hpart_5 (
LIKE hash_parted
) PARTITION BY LIST (b);
-- check that violating rows are correctly reported
CREATE TABLE hpart_5_a PARTITION OF hpart_5 FOR VALUES IN ('1', '2', '3');
INSERT INTO hpart_5_a (a, b) VALUES (7, 1);
ALTER TABLE hash_parted ATTACH PARTITION hpart_5 FOR VALUES WITH (MODULUS 4, REMAINDER 2);
-- should be ok after deleting the bad row
DELETE FROM hpart_5_a;
ALTER TABLE hash_parted ATTACH PARTITION hpart_5 FOR VALUES WITH (MODULUS 4, REMAINDER 2);
-- check that the table being attach is with valid modulus and remainder value
CREATE TABLE fail_part(LIKE hash_parted);
ALTER TABLE hash_parted ATTACH PARTITION fail_part FOR VALUES WITH (MODULUS 0, REMAINDER 1);
ALTER TABLE hash_parted ATTACH PARTITION fail_part FOR VALUES WITH (MODULUS 8, REMAINDER 8);
ALTER TABLE hash_parted ATTACH PARTITION fail_part FOR VALUES WITH (MODULUS 3, REMAINDER 2);
DROP TABLE fail_part;
--
-- DETACH PARTITION
--
......@@ -2343,12 +2400,16 @@ DROP TABLE regular_table;
-- check that the partition being detached exists at all
ALTER TABLE list_parted2 DETACH PARTITION part_4;
ALTER TABLE hash_parted DETACH PARTITION hpart_4;
-- check that the partition being detached is actually a partition of the parent
CREATE TABLE not_a_part (a int);
ALTER TABLE list_parted2 DETACH PARTITION not_a_part;
ALTER TABLE list_parted2 DETACH PARTITION part_1;
ALTER TABLE hash_parted DETACH PARTITION not_a_part;
DROP TABLE not_a_part;
-- check that, after being detached, attinhcount/coninhcount is dropped to 0 and
-- attislocal/conislocal is set to true
ALTER TABLE list_parted2 DETACH PARTITION part_3_4;
......@@ -2425,6 +2486,9 @@ SELECT * FROM list_parted;
-- cleanup
DROP TABLE list_parted, list_parted2, range_parted;
DROP TABLE fail_def_part;
DROP TABLE hash_parted;
DROP OPERATOR CLASS custom_opclass USING HASH;
DROP FUNCTION dummy_hashint4(a int4, seed int8);
-- more tests for certain multi-level partitioning scenarios
create table p (a int, b int) partition by range (a, b);
......
......@@ -350,10 +350,10 @@ CREATE TABLE partitioned (
) PARTITION BY RANGE (const_func());
DROP FUNCTION const_func();
-- only accept "list" and "range" as partitioning strategy
-- only accept valid partitioning strategy
CREATE TABLE partitioned (
a int
) PARTITION BY HASH (a);
a int
) PARTITION BY MAGIC (a);
-- specified column must be present in the table
CREATE TABLE partitioned (
......@@ -446,6 +446,8 @@ CREATE TABLE fail_part PARTITION OF list_parted FOR VALUES IN ('1'::int);
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);
-- trying to specify modulus and remainder for list partitioned table
CREATE TABLE fail_part PARTITION OF list_parted FOR VALUES WITH (MODULUS 10, REMAINDER 1);
-- check default partition cannot be created more than once
CREATE TABLE part_default PARTITION OF list_parted DEFAULT;
......@@ -481,6 +483,8 @@ CREATE TABLE range_parted (
-- trying to specify list for range partitioned table
CREATE TABLE fail_part PARTITION OF range_parted FOR VALUES IN ('a');
-- trying to specify modulus and remainder for range partitioned table
CREATE TABLE fail_part PARTITION OF range_parted FOR VALUES WITH (MODULUS 10, REMAINDER 1);
-- each of start and end bounds must have same number of values as the
-- length of the partition key
CREATE TABLE fail_part PARTITION OF range_parted FOR VALUES FROM ('a', 1) TO ('z');
......@@ -489,6 +493,28 @@ CREATE TABLE fail_part PARTITION OF range_parted FOR VALUES FROM ('a') TO ('z',
-- cannot specify null values in range bounds
CREATE TABLE fail_part PARTITION OF range_parted FOR VALUES FROM (null) TO (maxvalue);
-- trying to specify modulus and remainder for range partitioned table
CREATE TABLE fail_part PARTITION OF range_parted FOR VALUES WITH (MODULUS 10, REMAINDER 1);
-- check partition bound syntax for the hash partition
CREATE TABLE hash_parted (
a int
) PARTITION BY HASH (a);
CREATE TABLE hpart_1 PARTITION OF hash_parted FOR VALUES WITH (MODULUS 10, REMAINDER 0);
CREATE TABLE hpart_2 PARTITION OF hash_parted FOR VALUES WITH (MODULUS 50, REMAINDER 1);
CREATE TABLE hpart_3 PARTITION OF hash_parted FOR VALUES WITH (MODULUS 200, REMAINDER 2);
-- modulus 25 is factor of modulus of 50 but 10 is not factor of 25.
CREATE TABLE fail_part PARTITION OF hash_parted FOR VALUES WITH (MODULUS 25, REMAINDER 3);
-- previous modulus 50 is factor of 150 but this modulus is not factor of next modulus 200.
CREATE TABLE fail_part PARTITION OF hash_parted FOR VALUES WITH (MODULUS 150, REMAINDER 3);
-- trying to specify range for the hash partitioned table
CREATE TABLE fail_part PARTITION OF hash_parted FOR VALUES FROM ('a', 1) TO ('z');
-- trying to specify list value for the hash partitioned table
CREATE TABLE fail_part PARTITION OF hash_parted FOR VALUES IN (1000);
-- trying to create default partition for the hash partitioned table
CREATE TABLE fail_default_part PARTITION OF hash_parted DEFAULT;
-- check if compatible with the specified parent
-- cannot create as partition of a non-partitioned table
......@@ -496,6 +522,7 @@ CREATE TABLE unparted (
a int
);
CREATE TABLE fail_part PARTITION OF unparted FOR VALUES IN ('a');
CREATE TABLE fail_part PARTITION OF unparted FOR VALUES WITH (MODULUS 2, REMAINDER 1);
DROP TABLE unparted;
-- cannot create a permanent rel as partition of a temp rel
......@@ -585,6 +612,21 @@ CREATE TABLE range3_default PARTITION OF range_parted3 DEFAULT;
-- more specific ranges
CREATE TABLE fail_part PARTITION OF range_parted3 FOR VALUES FROM (1, minvalue) TO (1, maxvalue);
-- check for partition bound overlap and other invalid specifications for the hash partition
CREATE TABLE hash_parted2 (
a varchar
) PARTITION BY HASH (a);
CREATE TABLE h2part_1 PARTITION OF hash_parted2 FOR VALUES WITH (MODULUS 4, REMAINDER 2);
CREATE TABLE h2part_2 PARTITION OF hash_parted2 FOR VALUES WITH (MODULUS 8, REMAINDER 0);
CREATE TABLE h2part_3 PARTITION OF hash_parted2 FOR VALUES WITH (MODULUS 8, REMAINDER 4);
CREATE TABLE h2part_4 PARTITION OF hash_parted2 FOR VALUES WITH (MODULUS 8, REMAINDER 5);
-- overlap with part_4
CREATE TABLE fail_part PARTITION OF hash_parted2 FOR VALUES WITH (MODULUS 2, REMAINDER 1);
-- modulus must be greater than zero
CREATE TABLE fail_part PARTITION OF hash_parted2 FOR VALUES WITH (MODULUS 0, REMAINDER 1);
-- remainder must be greater than or equal to zero and less than modulus
CREATE TABLE fail_part PARTITION OF hash_parted2 FOR VALUES WITH (MODULUS 8, REMAINDER 8);
-- check schema propagation from parent
CREATE TABLE parted (
......@@ -638,6 +680,7 @@ CREATE TABLE part_c_1_10 PARTITION OF part_c FOR VALUES FROM (1) TO (10);
-- output could vary depending on the order in which partition oids are
-- returned.
\d parted
\d hash_parted
-- check that we get the expected partition constraints
CREATE TABLE range_parted4 (a int, b int, c int) PARTITION BY RANGE (abs(a), abs(b), c);
......@@ -654,6 +697,8 @@ DROP TABLE range_parted4;
-- cleanup
DROP TABLE parted, list_parted, range_parted, list_parted2, range_parted2, range_parted3;
DROP TABLE hash_parted;
DROP TABLE hash_parted2;
-- comments on partitioned tables columns
CREATE TABLE parted_col_comment (a int, b text) PARTITION BY LIST (a);
......
......@@ -222,8 +222,41 @@ insert into list_parted select 'gg', s.a from generate_series(1, 9) s(a);
insert into list_parted (b) values (1);
select tableoid::regclass::text, a, min(b) as min_b, max(b) as max_b from list_parted group by 1, 2 order by 1;
-- direct partition inserts should check hash partition bound constraint
-- create custom operator class and hash function, for the same reason
-- explained in alter_table.sql
create or replace function dummy_hashint4(a int4, seed int8) returns int8 as
$$ begin return (a + seed); end; $$ language 'plpgsql' immutable;
create operator class custom_opclass for type int4 using hash as
operator 1 = , function 2 dummy_hashint4(int4, int8);
create table hash_parted (
a int
) partition by hash (a custom_opclass);
create table hpart0 partition of hash_parted for values with (modulus 4, remainder 0);
create table hpart1 partition of hash_parted for values with (modulus 4, remainder 1);
create table hpart2 partition of hash_parted for values with (modulus 4, remainder 2);
create table hpart3 partition of hash_parted for values with (modulus 4, remainder 3);
insert into hash_parted values(generate_series(1,10));
-- direct insert of values divisible by 4 - ok;
insert into hpart0 values(12),(16);
-- fail;
insert into hpart0 values(11);
-- 11 % 4 -> 3 remainder i.e. valid data for hpart3 partition
insert into hpart3 values(11);
-- view data
select tableoid::regclass as part, a, a%4 as "remainder = a % 4"
from hash_parted order by part;
-- cleanup
drop table range_parted, list_parted;
drop table hash_parted;
drop operator class custom_opclass using hash;
drop function dummy_hashint4(a int4, seed int8);
-- test that a default partition added as the first partition accepts any value
-- including null
......
......@@ -229,6 +229,38 @@ SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1
EXPLAIN (COSTS OFF)
SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a = 1 AND a = 2) t1 FULL JOIN prt2 t2 ON t1.a = t2.b WHERE t2.a = 0 ORDER BY t1.a, t2.b;
--
-- tests for hash partitioned tables.
--
CREATE TABLE pht1 (a int, b int, c text) PARTITION BY HASH(c);
CREATE TABLE pht1_p1 PARTITION OF pht1 FOR VALUES WITH (MODULUS 3, REMAINDER 0);
CREATE TABLE pht1_p2 PARTITION OF pht1 FOR VALUES WITH (MODULUS 3, REMAINDER 1);
CREATE TABLE pht1_p3 PARTITION OF pht1 FOR VALUES WITH (MODULUS 3, REMAINDER 2);
INSERT INTO pht1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
ANALYZE pht1;
CREATE TABLE pht2 (a int, b int, c text) PARTITION BY HASH(c);
CREATE TABLE pht2_p1 PARTITION OF pht2 FOR VALUES WITH (MODULUS 3, REMAINDER 0);
CREATE TABLE pht2_p2 PARTITION OF pht2 FOR VALUES WITH (MODULUS 3, REMAINDER 1);
CREATE TABLE pht2_p3 PARTITION OF pht2 FOR VALUES WITH (MODULUS 3, REMAINDER 2);
INSERT INTO pht2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 599, 3) i;
ANALYZE pht2;
--
-- hash partitioned by expression
--
CREATE TABLE pht1_e (a int, b int, c text) PARTITION BY HASH(ltrim(c, 'A'));
CREATE TABLE pht1_e_p1 PARTITION OF pht1_e FOR VALUES WITH (MODULUS 3, REMAINDER 0);
CREATE TABLE pht1_e_p2 PARTITION OF pht1_e FOR VALUES WITH (MODULUS 3, REMAINDER 1);
CREATE TABLE pht1_e_p3 PARTITION OF pht1_e FOR VALUES WITH (MODULUS 3, REMAINDER 2);
INSERT INTO pht1_e SELECT i, i, 'A' || to_char(i/50, 'FM0000') FROM generate_series(0, 599, 2) i;
ANALYZE pht1_e;
-- test partition matching with N-way join
EXPLAIN (COSTS OFF)
SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM pht1 t1, pht2 t2, pht1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
SELECT avg(t1.a), avg(t2.b), avg(t3.a + t3.b), t1.c, t2.c, t3.c FROM pht1 t1, pht2 t2, pht1_e t3 WHERE t1.c = t2.c AND ltrim(t3.c, 'A') = t1.c GROUP BY t1.c, t2.c, t3.c ORDER BY t1.c, t2.c, t3.c;
--
-- multiple levels of partitioning
--
......
......@@ -148,6 +148,34 @@ update list_default set a = 'a' where a = 'd';
-- ok
update list_default set a = 'x' where a = 'd';
-- create custom operator class and hash function, for the same reason
-- explained in alter_table.sql
create or replace function dummy_hashint4(a int4, seed int8) returns int8 as
$$ begin return (a + seed); end; $$ language 'plpgsql' immutable;
create operator class custom_opclass for type int4 using hash as
operator 1 = , function 2 dummy_hashint4(int4, int8);
create table hash_parted (
a int,
b int
) partition by hash (a custom_opclass, b custom_opclass);
create table hpart1 partition of hash_parted for values with (modulus 2, remainder 1);
create table hpart2 partition of hash_parted for values with (modulus 4, remainder 2);
create table hpart3 partition of hash_parted for values with (modulus 8, remainder 0);
create table hpart4 partition of hash_parted for values with (modulus 8, remainder 4);
insert into hpart1 values (1, 1);
insert into hpart2 values (2, 5);
insert into hpart4 values (3, 4);
-- fail
update hpart1 set a = 3, b=4 where a = 1;
update hash_parted set b = b - 1 where b = 1;
-- ok
update hash_parted set b = b + 8 where b = 1;
-- cleanup
drop table range_parted;
drop table list_parted;
drop table hash_parted;
drop operator class custom_opclass using hash;
drop function dummy_hashint4(a int4, seed int8);
......@@ -1565,6 +1565,7 @@ PartitionDispatch
PartitionDispatchData
PartitionElem
PartitionKey
PartitionHashBound
PartitionListValue
PartitionRangeBound
PartitionRangeDatum
......
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