Skip to content

Commit 99d3f28

Browse files
author
Commitfest Bot
committed
[CF 5720] v1 - virtual generated column as partition key
This branch was automatically generated by a robot using patches from an email thread registered at: https://commitfest.postgresql.org/patch/5720 The branch will be overwritten each time a new patch version is posted to the thread, and also periodically to check for bitrot caused by changes on the master branch. Patch(es): https://www.postgresql.org/message-id/CACJufxF9RV2_iHBAG0AfCyt5c-1zJkh_Jc7F1tZfk3m3N+E=qA@mail.gmail.com Author(s): Jian He
2 parents f0f2c0c + 676ac8a commit 99d3f28

File tree

10 files changed

+467
-139
lines changed

10 files changed

+467
-139
lines changed

src/backend/commands/tablecmds.c

Lines changed: 254 additions & 109 deletions
Large diffs are not rendered by default.

src/backend/executor/execPartition.c

Lines changed: 2 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1325,7 +1325,8 @@ FormPartitionKeyDatum(PartitionDispatch pd,
13251325
Datum datum;
13261326
bool isNull;
13271327

1328-
if (keycol != 0)
1328+
if (keycol != 0 &&
1329+
RelationGetColumnGenerated(pd->reldesc, keycol) != ATTRIBUTE_GENERATED_VIRTUAL)
13291330
{
13301331
/* Plain column; get the value directly from the heap tuple */
13311332
datum = slot_getattr(slot, keycol, &isNull);

src/backend/partitioning/partbounds.c

Lines changed: 19 additions & 13 deletions
Original file line numberDiff line numberDiff line change
@@ -232,13 +232,13 @@ static List *get_qual_for_hash(Relation parent, PartitionBoundSpec *spec);
232232
static List *get_qual_for_list(Relation parent, PartitionBoundSpec *spec);
233233
static List *get_qual_for_range(Relation parent, PartitionBoundSpec *spec,
234234
bool for_default);
235-
static void get_range_key_properties(PartitionKey key, int keynum,
235+
static void get_range_key_properties(Relation rel, PartitionKey key, int keynum,
236236
PartitionRangeDatum *ldatum,
237237
PartitionRangeDatum *udatum,
238238
ListCell **partexprs_item,
239239
Expr **keyCol,
240240
Const **lower_val, Const **upper_val);
241-
static List *get_range_nulltest(PartitionKey key);
241+
static List *get_range_nulltest(Relation rel, PartitionKey key);
242242

243243
/*
244244
* get_qual_from_partbound
@@ -4026,7 +4026,8 @@ get_qual_for_hash(Relation parent, PartitionBoundSpec *spec)
40264026
Node *keyCol;
40274027

40284028
/* Left operand */
4029-
if (key->partattrs[i] != 0)
4029+
if (key->partattrs[i] != 0 &&
4030+
RelationGetColumnGenerated(parent, key->partattrs[i]) != ATTRIBUTE_GENERATED_VIRTUAL)
40304031
{
40314032
keyCol = (Node *) makeVar(1,
40324033
key->partattrs[i],
@@ -4082,7 +4083,8 @@ get_qual_for_list(Relation parent, PartitionBoundSpec *spec)
40824083
Assert(key->partnatts == 1);
40834084

40844085
/* Construct Var or expression representing the partition column */
4085-
if (key->partattrs[0] != 0)
4086+
if (key->partattrs[0] != 0 &&
4087+
RelationGetColumnGenerated(parent, key->partattrs[0]) != ATTRIBUTE_GENERATED_VIRTUAL)
40864088
keyCol = (Expr *) makeVar(1,
40874089
key->partattrs[0],
40884090
key->parttypid[0],
@@ -4353,7 +4355,7 @@ get_qual_for_range(Relation parent, PartitionBoundSpec *spec,
43534355
*/
43544356
other_parts_constr =
43554357
makeBoolExpr(AND_EXPR,
4356-
lappend(get_range_nulltest(key),
4358+
lappend(get_range_nulltest(parent, key),
43574359
list_length(or_expr_args) > 1
43584360
? makeBoolExpr(OR_EXPR, or_expr_args,
43594361
-1)
@@ -4376,7 +4378,7 @@ get_qual_for_range(Relation parent, PartitionBoundSpec *spec,
43764378
* to avoid accumulating the NullTest on the same keys for each partition.
43774379
*/
43784380
if (!for_default)
4379-
result = get_range_nulltest(key);
4381+
result = get_range_nulltest(parent, key);
43804382

43814383
/*
43824384
* Iterate over the key columns and check if the corresponding lower and
@@ -4408,7 +4410,7 @@ get_qual_for_range(Relation parent, PartitionBoundSpec *spec,
44084410
*/
44094411
partexprs_item_saved = partexprs_item;
44104412

4411-
get_range_key_properties(key, i, ldatum, udatum,
4413+
get_range_key_properties(parent, key, i, ldatum, udatum,
44124414
&partexprs_item,
44134415
&keyCol,
44144416
&lower_val, &upper_val);
@@ -4488,7 +4490,7 @@ get_qual_for_range(Relation parent, PartitionBoundSpec *spec,
44884490
if (lnext(spec->upperdatums, cell2))
44894491
udatum_next = castNode(PartitionRangeDatum,
44904492
lfirst(lnext(spec->upperdatums, cell2)));
4491-
get_range_key_properties(key, j, ldatum, udatum,
4493+
get_range_key_properties(parent, key, j, ldatum, udatum,
44924494
&partexprs_item,
44934495
&keyCol,
44944496
&lower_val, &upper_val);
@@ -4608,7 +4610,7 @@ get_qual_for_range(Relation parent, PartitionBoundSpec *spec,
46084610
*/
46094611
if (result == NIL)
46104612
result = for_default
4611-
? get_range_nulltest(key)
4613+
? get_range_nulltest(parent, key)
46124614
: list_make1(makeBoolConst(true, false));
46134615

46144616
return result;
@@ -4630,15 +4632,16 @@ get_qual_for_range(Relation parent, PartitionBoundSpec *spec,
46304632
* the key->partexprs list, or NULL. It may be advanced upon return.
46314633
*/
46324634
static void
4633-
get_range_key_properties(PartitionKey key, int keynum,
4635+
get_range_key_properties(Relation rel, PartitionKey key, int keynum,
46344636
PartitionRangeDatum *ldatum,
46354637
PartitionRangeDatum *udatum,
46364638
ListCell **partexprs_item,
46374639
Expr **keyCol,
46384640
Const **lower_val, Const **upper_val)
46394641
{
46404642
/* Get partition key expression for this column */
4641-
if (key->partattrs[keynum] != 0)
4643+
if (key->partattrs[keynum] != 0 &&
4644+
RelationGetColumnGenerated(rel, key->partattrs[keynum]) != ATTRIBUTE_GENERATED_VIRTUAL)
46424645
{
46434646
*keyCol = (Expr *) makeVar(1,
46444647
key->partattrs[keynum],
@@ -4674,7 +4677,7 @@ get_range_key_properties(PartitionKey key, int keynum,
46744677
* keys to be null, so emit an IS NOT NULL expression for each key column.
46754678
*/
46764679
static List *
4677-
get_range_nulltest(PartitionKey key)
4680+
get_range_nulltest(Relation rel, PartitionKey key)
46784681
{
46794682
List *result = NIL;
46804683
NullTest *nulltest;
@@ -4685,8 +4688,11 @@ get_range_nulltest(PartitionKey key)
46854688
for (i = 0; i < key->partnatts; i++)
46864689
{
46874690
Expr *keyCol;
4691+
bool key_virtual;
46884692

4689-
if (key->partattrs[i] != 0)
4693+
key_virtual = (RelationGetColumnGenerated(rel, key->partattrs[i]) == ATTRIBUTE_GENERATED_VIRTUAL);
4694+
4695+
if (key->partattrs[i] != 0 && !key_virtual)
46904696
{
46914697
keyCol = (Expr *) makeVar(1,
46924698
key->partattrs[i],

src/backend/utils/cache/partcache.c

Lines changed: 4 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -194,6 +194,7 @@ RelationBuildPartitionKey(Relation relation)
194194
HeapTuple opclasstup;
195195
Form_pg_opclass opclassform;
196196
Oid funcid;
197+
bool key_virtual;
197198

198199
/* Collect opfamily information */
199200
opclasstup = SearchSysCache1(CLAOID,
@@ -225,8 +226,10 @@ RelationBuildPartitionKey(Relation relation)
225226
/* Collation */
226227
key->partcollation[i] = collation->values[i];
227228

229+
key_virtual = (RelationGetColumnGenerated(relation, attno) == ATTRIBUTE_GENERATED_VIRTUAL);
230+
228231
/* Collect type information */
229-
if (attno != 0)
232+
if (attno != 0 && !key_virtual)
230233
{
231234
Form_pg_attribute att = TupleDescAttr(relation->rd_att, attno - 1);
232235

src/backend/utils/cache/relcache.c

Lines changed: 13 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -6033,6 +6033,19 @@ RelationGetIndexAttOptions(Relation relation, bool copy)
60336033
return relation->rd_opcoptions;
60346034
}
60356035

6036+
char
6037+
RelationGetColumnGenerated(Relation rel, int attnum)
6038+
{
6039+
TupleDesc tupdesc;
6040+
Form_pg_attribute attr;
6041+
6042+
tupdesc = RelationGetDescr(rel);
6043+
6044+
attr = TupleDescAttr(tupdesc, attnum -1);
6045+
6046+
return attr->attgenerated;
6047+
}
6048+
60366049
/*
60376050
* Routines to support ereport() reports of relation-related errors
60386051
*

src/include/utils/relcache.h

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -60,6 +60,7 @@ extern List *RelationGetIndexExpressions(Relation relation);
6060
extern List *RelationGetDummyIndexExpressions(Relation relation);
6161
extern List *RelationGetIndexPredicate(Relation relation);
6262
extern bytea **RelationGetIndexAttOptions(Relation relation, bool copy);
63+
extern char RelationGetColumnGenerated(Relation relation, int attnum);
6364

6465
/*
6566
* Which set of columns to return by RelationGetIndexAttrBitmap.

src/test/regress/expected/generated_stored.out

Lines changed: 8 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -1070,15 +1070,20 @@ SELECT tableoid::regclass, * FROM gtest_parent ORDER BY 1, 2, 3;
10701070
-- we leave these tables around for purposes of testing dump/reload/upgrade
10711071
-- generated columns in partition key (not allowed)
10721072
CREATE TABLE gtest_part_key (f1 date NOT NULL, f2 bigint, f3 bigint GENERATED ALWAYS AS (f2 * 2) STORED) PARTITION BY RANGE (f3);
1073-
ERROR: cannot use generated column in partition key
1073+
ERROR: cannot use stored generated column in partition key
10741074
LINE 1: ...ENERATED ALWAYS AS (f2 * 2) STORED) PARTITION BY RANGE (f3);
10751075
^
1076+
DETAIL: Column "f3" is a stored generated column.
1077+
CREATE TABLE gtest_part_key (f1 date NOT NULL, f2 bigint, f3 bigint GENERATED ALWAYS AS (f2 * 2) STORED) PARTITION BY RANGE ((f3));
1078+
ERROR: cannot use stored generated column in partition key
1079+
LINE 1: ...ERATED ALWAYS AS (f2 * 2) STORED) PARTITION BY RANGE ((f3));
1080+
^
10761081
DETAIL: Column "f3" is a generated column.
10771082
CREATE TABLE gtest_part_key (f1 date NOT NULL, f2 bigint, f3 bigint GENERATED ALWAYS AS (f2 * 2) STORED) PARTITION BY RANGE ((f3 * 3));
1078-
ERROR: cannot use generated column in partition key
1083+
ERROR: cannot use stored generated column in partition key
10791084
LINE 1: ...ED ALWAYS AS (f2 * 2) STORED) PARTITION BY RANGE ((f3 * 3));
10801085
^
1081-
DETAIL: Column "f3" is a generated column.
1086+
DETAIL: Column "f3" is a stored generated column.
10821087
-- ALTER TABLE ... ADD COLUMN
10831088
CREATE TABLE gtest25 (a int PRIMARY KEY);
10841089
INSERT INTO gtest25 VALUES (3), (4);

src/test/regress/expected/generated_virtual.out

Lines changed: 104 additions & 9 deletions
Original file line numberDiff line numberDiff line change
@@ -1030,17 +1030,112 @@ SELECT tableoid::regclass, * FROM gtest_parent ORDER BY 1, 2, 3;
10301030
(3 rows)
10311031

10321032
-- we leave these tables around for purposes of testing dump/reload/upgrade
1033-
-- generated columns in partition key (not allowed)
1034-
CREATE TABLE gtest_part_key (f1 date NOT NULL, f2 bigint, f3 bigint GENERATED ALWAYS AS (f2 * 2) VIRTUAL) PARTITION BY RANGE (f3);
1035-
ERROR: cannot use generated column in partition key
1036-
LINE 1: ...NERATED ALWAYS AS (f2 * 2) VIRTUAL) PARTITION BY RANGE (f3);
1037-
^
1038-
DETAIL: Column "f3" is a generated column.
1039-
CREATE TABLE gtest_part_key (f1 date NOT NULL, f2 bigint, f3 bigint GENERATED ALWAYS AS (f2 * 2) VIRTUAL) PARTITION BY RANGE ((f3 * 3));
1040-
ERROR: cannot use generated column in partition key
1033+
-- tests for virtual generated columns in partition key
1034+
CREATE TABLE gtest_part_key1 (f1 date, f2 bigint, f3 bigint GENERATED ALWAYS AS (f2 * 2) VIRTUAL) PARTITION BY RANGE ((f3 * 3)); --error
1035+
ERROR: partition key expression cannot use virtual generated column
10411036
LINE 1: ...D ALWAYS AS (f2 * 2) VIRTUAL) PARTITION BY RANGE ((f3 * 3));
10421037
^
1043-
DETAIL: Column "f3" is a generated column.
1038+
HINT: Only plain virtual generated column reference can be used in partition key
1039+
CREATE TABLE gtest_part_key1 (f1 date, f2 bigint, f3 bigint GENERATED ALWAYS AS (f2 * 2) VIRTUAL) PARTITION BY RANGE ((f3)); --ok
1040+
ALTER TABLE gtest_part_key1 ALTER COLUMN f3 SET EXPRESSION AS (f2 * 2); --error
1041+
ERROR: cannot alter column "f3" because it is part of the partition key of relation "gtest_part_key1"
1042+
ALTER TABLE gtest_part_key1 ALTER COLUMN f2 set data type int; --error
1043+
ERROR: cannot alter type of a column used by a generated column
1044+
DETAIL: Column "f2" is used by generated column "f3".
1045+
ALTER TABLE gtest_part_key1 ALTER COLUMN f3 set data type int; --error
1046+
ERROR: cannot alter column "f3" because it is part of the partition key of relation "gtest_part_key1"
1047+
LINE 1: ALTER TABLE gtest_part_key1 ALTER COLUMN f3 set data type in...
1048+
^
1049+
CREATE TABLE gtest_part_key1_0(f2 bigint, f1 date, f3 bigint GENERATED ALWAYS AS (f2 * 3) VIRTUAL);
1050+
ALTER TABLE gtest_part_key1 ATTACH PARTITION gtest_part_key1_0 FOR VALUES FROM (20) TO (30); --error
1051+
ERROR: cannot attach table "gtest_part_key1_0" as a partition because it has with different generation expression
1052+
ALTER TABLE gtest_part_key1_0 ALTER COLUMN f3 SET EXPRESSION AS (f2 * 2);
1053+
ALTER TABLE gtest_part_key1 ATTACH PARTITION gtest_part_key1_0 FOR VALUES FROM (20) TO (30); --now ok
1054+
CREATE TABLE gtest_part_key1_1 PARTITION OF gtest_part_key1 FOR VALUES FROM (30) TO (50);
1055+
CREATE TABLE gtest_part_key1_2 PARTITION OF gtest_part_key1 FOR VALUES FROM (50) TO (100);
1056+
\d+ gtest_part_key1
1057+
Partitioned table "generated_virtual_tests.gtest_part_key1"
1058+
Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
1059+
--------+--------+-----------+----------+------------------------------+---------+--------------+-------------
1060+
f1 | date | | | | plain | |
1061+
f2 | bigint | | | | plain | |
1062+
f3 | bigint | | | generated always as (f2 * 2) | plain | |
1063+
Partition key: RANGE (f3)
1064+
Partitions: gtest_part_key1_0 FOR VALUES FROM ('20') TO ('30'),
1065+
gtest_part_key1_1 FOR VALUES FROM ('30') TO ('50'),
1066+
gtest_part_key1_2 FOR VALUES FROM ('50') TO ('100')
1067+
1068+
CREATE OR REPLACE FUNCTION gtest_trigger_info() RETURNS trigger
1069+
LANGUAGE plpgsql
1070+
AS $$
1071+
BEGIN
1072+
RAISE INFO 'TG_WHEN: % TG_RELNAME: % trigger name: % tg_op: %', TG_WHEN, TG_relname, TG_NAME, tg_op;
1073+
IF tg_op IN ('DELETE') THEN
1074+
RAISE INFO 'old = %', OLD;
1075+
RETURN OLD;
1076+
ELSIF tg_op IN ('INSERT') THEN
1077+
RAISE INFO 'new = %', NEW;
1078+
RETURN NEW;
1079+
ELSIF tg_op IN ('UPDATE') THEN
1080+
RAISE INFO 'old = %d; new = %', OLD, NEW;
1081+
RETURN NEW;
1082+
ELSE
1083+
RETURN NEW;
1084+
END IF;
1085+
END
1086+
$$;
1087+
CREATE TRIGGER gkey1_0 BEFORE INSERT OR UPDATE ON gtest_part_key1_0
1088+
FOR EACH ROW
1089+
EXECUTE PROCEDURE gtest_trigger_info();
1090+
CREATE TRIGGER gkey1_1 BEFORE INSERT OR UPDATE ON gtest_part_key1_1
1091+
FOR EACH ROW
1092+
EXECUTE PROCEDURE gtest_trigger_info();
1093+
CREATE TRIGGER gkey1_2 BEFORE INSERT OR UPDATE ON gtest_part_key1_2
1094+
FOR EACH ROW
1095+
EXECUTE PROCEDURE gtest_trigger_info();
1096+
INSERT INTO gtest_part_key1(f2, f3) VALUES (9, default); --error
1097+
ERROR: no partition of relation "gtest_part_key1" found for row
1098+
DETAIL: Partition key of the failing row contains (f3) = (18).
1099+
INSERT INTO gtest_part_key1(f2, f3) VALUES (10, default) returning tableoid::regclass, *; --ok
1100+
INFO: TG_WHEN: BEFORE TG_RELNAME: gtest_part_key1_0 trigger name: gkey1_0 tg_op: INSERT
1101+
INFO: new = (10,,)
1102+
tableoid | f1 | f2 | f3
1103+
-------------------+----+----+----
1104+
gtest_part_key1_0 | | 10 | 20
1105+
(1 row)
1106+
1107+
INSERT INTO gtest_part_key1_0(f2, f3) VALUES (12, default) returning tableoid::regclass, *; --ok
1108+
INFO: TG_WHEN: BEFORE TG_RELNAME: gtest_part_key1_0 trigger name: gkey1_0 tg_op: INSERT
1109+
INFO: new = (12,,)
1110+
tableoid | f2 | f1 | f3
1111+
-------------------+----+----+----
1112+
gtest_part_key1_0 | 12 | | 24
1113+
(1 row)
1114+
1115+
MERGE INTO gtest_part_key1
1116+
USING (VALUES (10, 100), (12, 25), (14, 30)) AS s(sid, delta)
1117+
ON gtest_part_key1.f2 = s.sid
1118+
WHEN MATCHED AND f2 = 12 THEN UPDATE SET f2 = 20
1119+
WHEN MATCHED AND f2 = 10 THEN UPDATE SET f2 = 30
1120+
WHEN NOT MATCHED THEN INSERT(f2) VALUES (s.sid)
1121+
RETURNING merge_action(), tableoid::regclass, old.f2, old.f3, new.f2, new.f3;
1122+
INFO: TG_WHEN: BEFORE TG_RELNAME: gtest_part_key1_0 trigger name: gkey1_0 tg_op: UPDATE
1123+
INFO: old = (10,,)d; new = (30,,)
1124+
INFO: TG_WHEN: BEFORE TG_RELNAME: gtest_part_key1_2 trigger name: gkey1_2 tg_op: INSERT
1125+
INFO: new = (,30,)
1126+
INFO: TG_WHEN: BEFORE TG_RELNAME: gtest_part_key1_0 trigger name: gkey1_0 tg_op: UPDATE
1127+
INFO: old = (12,,)d; new = (20,,)
1128+
INFO: TG_WHEN: BEFORE TG_RELNAME: gtest_part_key1_1 trigger name: gkey1_1 tg_op: INSERT
1129+
INFO: new = (,20,)
1130+
INFO: TG_WHEN: BEFORE TG_RELNAME: gtest_part_key1_0 trigger name: gkey1_0 tg_op: INSERT
1131+
INFO: new = (14,,)
1132+
merge_action | tableoid | f2 | f3 | f2 | f3
1133+
--------------+-------------------+----+----+----+----
1134+
UPDATE | gtest_part_key1_2 | 10 | 20 | 30 | 60
1135+
UPDATE | gtest_part_key1_1 | 12 | 24 | 20 | 40
1136+
INSERT | gtest_part_key1_0 | | | 14 | 28
1137+
(3 rows)
1138+
10441139
-- ALTER TABLE ... ADD COLUMN
10451140
CREATE TABLE gtest25 (a int PRIMARY KEY);
10461141
INSERT INTO gtest25 VALUES (3), (4);

src/test/regress/sql/generated_stored.sql

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -500,6 +500,7 @@ SELECT tableoid::regclass, * FROM gtest_parent ORDER BY 1, 2, 3;
500500

501501
-- generated columns in partition key (not allowed)
502502
CREATE TABLE gtest_part_key (f1 date NOT NULL, f2 bigint, f3 bigint GENERATED ALWAYS AS (f2 * 2) STORED) PARTITION BY RANGE (f3);
503+
CREATE TABLE gtest_part_key (f1 date NOT NULL, f2 bigint, f3 bigint GENERATED ALWAYS AS (f2 * 2) STORED) PARTITION BY RANGE ((f3));
503504
CREATE TABLE gtest_part_key (f1 date NOT NULL, f2 bigint, f3 bigint GENERATED ALWAYS AS (f2 * 2) STORED) PARTITION BY RANGE ((f3 * 3));
504505

505506
-- ALTER TABLE ... ADD COLUMN

0 commit comments

Comments
 (0)