diff options
Diffstat (limited to 'src')
-rw-r--r-- | src/backend/commands/tablecmds.c | 235 | ||||
-rw-r--r-- | src/backend/parser/gram.y | 10 | ||||
-rw-r--r-- | src/bin/psql/tab-complete.c | 10 | ||||
-rw-r--r-- | src/include/nodes/parsenodes.h | 1 | ||||
-rw-r--r-- | src/test/modules/test_ddl_deparse/test_ddl_deparse.c | 3 | ||||
-rw-r--r-- | src/test/regress/expected/generated.out | 217 | ||||
-rw-r--r-- | src/test/regress/sql/generated.sql | 52 |
7 files changed, 448 insertions, 80 deletions
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c index d39433fc902..2822b2bb440 100644 --- a/src/backend/commands/tablecmds.c +++ b/src/backend/commands/tablecmds.c @@ -147,10 +147,11 @@ typedef enum AlterTablePass AT_PASS_UNSET = -1, /* UNSET will cause ERROR */ AT_PASS_DROP, /* DROP (all flavors) */ AT_PASS_ALTER_TYPE, /* ALTER COLUMN TYPE */ + AT_PASS_ADD_COL, /* ADD COLUMN */ + AT_PASS_SET_EXPRESSION, /* ALTER SET EXPRESSION */ AT_PASS_OLD_INDEX, /* re-add existing indexes */ AT_PASS_OLD_CONSTR, /* re-add existing constraints */ /* We could support a RENAME COLUMN pass here, but not currently used */ - AT_PASS_ADD_COL, /* ADD COLUMN */ AT_PASS_ADD_CONSTR, /* ADD constraints (initial examination) */ AT_PASS_COL_ATTRS, /* set column attributes, eg NOT NULL */ AT_PASS_ADD_INDEXCONSTR, /* ADD index-based constraints */ @@ -459,6 +460,8 @@ static ObjectAddress ATExecAddIdentity(Relation rel, const char *colName, static ObjectAddress ATExecSetIdentity(Relation rel, const char *colName, Node *def, LOCKMODE lockmode); static ObjectAddress ATExecDropIdentity(Relation rel, const char *colName, bool missing_ok, LOCKMODE lockmode); +static ObjectAddress ATExecSetExpression(AlteredTableInfo *tab, Relation rel, const char *colName, + Node *newExpr, LOCKMODE lockmode); static void ATPrepDropExpression(Relation rel, AlterTableCmd *cmd, bool recurse, bool recursing, LOCKMODE lockmode); static ObjectAddress ATExecDropExpression(Relation rel, const char *colName, bool missing_ok, LOCKMODE lockmode); static ObjectAddress ATExecSetStatistics(Relation rel, const char *colName, int16 colNum, @@ -561,7 +564,7 @@ static void ATPrepAlterColumnType(List **wqueue, static bool ATColumnChangeRequiresRewrite(Node *expr, AttrNumber varattno); static ObjectAddress ATExecAlterColumnType(AlteredTableInfo *tab, Relation rel, AlterTableCmd *cmd, LOCKMODE lockmode); -static void RememberAllDependentForRebuilding(AlteredTableInfo *tab, +static void RememberAllDependentForRebuilding(AlteredTableInfo *tab, AlterTableType subtype, Relation rel, AttrNumber attnum, const char *colName); static void RememberConstraintForRebuilding(Oid conoid, AlteredTableInfo *tab); static void RememberIndexForRebuilding(Oid indoid, AlteredTableInfo *tab); @@ -4551,6 +4554,7 @@ AlterTableGetLockLevel(List *cmds) case AT_AddIdentity: case AT_DropIdentity: case AT_SetIdentity: + case AT_SetExpression: case AT_DropExpression: case AT_SetCompression: cmd_lockmode = AccessExclusiveLock; @@ -4852,6 +4856,11 @@ ATPrepCmd(List **wqueue, Relation rel, AlterTableCmd *cmd, ATSimpleRecursion(wqueue, rel, cmd, recurse, lockmode, context); pass = AT_PASS_COL_ATTRS; break; + case AT_SetExpression: /* ALTER COLUMN SET EXPRESSION */ + ATSimplePermissions(cmd->subtype, rel, ATT_TABLE | ATT_FOREIGN_TABLE); + ATSimpleRecursion(wqueue, rel, cmd, recurse, lockmode, context); + pass = AT_PASS_SET_EXPRESSION; + break; case AT_DropExpression: /* ALTER COLUMN DROP EXPRESSION */ ATSimplePermissions(cmd->subtype, rel, ATT_TABLE | ATT_FOREIGN_TABLE); ATSimpleRecursion(wqueue, rel, cmd, recurse, lockmode, context); @@ -5153,11 +5162,11 @@ ATRewriteCatalogs(List **wqueue, LOCKMODE lockmode, lockmode, pass, context); /* - * After the ALTER TYPE pass, do cleanup work (this is not done in - * ATExecAlterColumnType since it should be done only once if - * multiple columns of a table are altered). + * After the ALTER TYPE or SET EXPRESSION pass, do cleanup work + * (this is not done in ATExecAlterColumnType since it should be + * done only once if multiple columns of a table are altered). */ - if (pass == AT_PASS_ALTER_TYPE) + if (pass == AT_PASS_ALTER_TYPE || pass == AT_PASS_SET_EXPRESSION) ATPostAlterTypeCleanup(wqueue, tab, lockmode); if (tab->rel) @@ -5236,6 +5245,9 @@ ATExecCmd(List **wqueue, AlteredTableInfo *tab, case AT_SetAttNotNull: /* set pg_attribute.attnotnull */ address = ATExecSetAttNotNull(wqueue, rel, cmd->name, lockmode); break; + case AT_SetExpression: + address = ATExecSetExpression(tab, rel, cmd->name, cmd->def, lockmode); + break; case AT_DropExpression: address = ATExecDropExpression(rel, cmd->name, cmd->missing_ok, lockmode); break; @@ -6363,6 +6375,8 @@ alter_table_type_to_string(AlterTableType cmdtype) return "ALTER COLUMN ... SET NOT NULL"; case AT_SetAttNotNull: return NULL; /* not real grammar */ + case AT_SetExpression: + return "ALTER COLUMN ... SET EXPRESSION"; case AT_DropExpression: return "ALTER COLUMN ... DROP EXPRESSION"; case AT_SetStatistics: @@ -8013,10 +8027,11 @@ ATExecColumnDefault(Relation rel, const char *colName, (errcode(ERRCODE_SYNTAX_ERROR), errmsg("column \"%s\" of relation \"%s\" is a generated column", colName, RelationGetRelationName(rel)), - newDefault || TupleDescAttr(tupdesc, attnum - 1)->attgenerated != ATTRIBUTE_GENERATED_STORED ? 0 : + newDefault ? /* translator: %s is an SQL ALTER command */ - errhint("Use %s instead.", - "ALTER TABLE ... ALTER COLUMN ... DROP EXPRESSION"))); + errhint("Use %s instead.", "ALTER TABLE ... ALTER COLUMN ... SET EXPRESSION") : + (TupleDescAttr(tupdesc, attnum - 1)->attgenerated == ATTRIBUTE_GENERATED_STORED ? + errhint("Use %s instead.", "ALTER TABLE ... ALTER COLUMN ... DROP EXPRESSION") : 0))); /* * Remove any old default for the column. We use RESTRICT here for @@ -8314,6 +8329,121 @@ ATExecDropIdentity(Relation rel, const char *colName, bool missing_ok, LOCKMODE } /* + * ALTER TABLE ALTER COLUMN SET EXPRESSION + * + * Return the address of the affected column. + */ +static ObjectAddress +ATExecSetExpression(AlteredTableInfo *tab, Relation rel, const char *colName, + Node *newExpr, LOCKMODE lockmode) +{ + HeapTuple tuple; + Form_pg_attribute attTup; + AttrNumber attnum; + Oid attrdefoid; + ObjectAddress address; + Expr *defval; + NewColumnValue *newval; + RawColumnDefault *rawEnt; + + tuple = SearchSysCacheAttName(RelationGetRelid(rel), colName); + if (!HeapTupleIsValid(tuple)) + ereport(ERROR, + (errcode(ERRCODE_UNDEFINED_COLUMN), + errmsg("column \"%s\" of relation \"%s\" does not exist", + colName, RelationGetRelationName(rel)))); + + attTup = (Form_pg_attribute) GETSTRUCT(tuple); + attnum = attTup->attnum; + + if (attnum <= 0) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("cannot alter system column \"%s\"", + colName))); + + if (attTup->attgenerated != ATTRIBUTE_GENERATED_STORED) + ereport(ERROR, + (errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE), + errmsg("column \"%s\" of relation \"%s\" is not a generated column", + colName, RelationGetRelationName(rel)))); + ReleaseSysCache(tuple); + + /* + * Clear all the missing values if we're rewriting the table, since this + * renders them pointless. + */ + RelationClearMissing(rel); + + /* make sure we don't conflict with later attribute modifications */ + CommandCounterIncrement(); + + /* + * Find everything that depends on the column (constraints, indexes, etc), + * and record enough information to let us recreate the objects after + * rewrite. + */ + RememberAllDependentForRebuilding(tab, AT_SetExpression, rel, attnum, colName); + + /* + * Drop the dependency records of the GENERATED expression, in particular + * its INTERNAL dependency on the column, which would otherwise cause + * dependency.c to refuse to perform the deletion. + */ + attrdefoid = GetAttrDefaultOid(RelationGetRelid(rel), attnum); + if (!OidIsValid(attrdefoid)) + elog(ERROR, "could not find attrdef tuple for relation %u attnum %d", + RelationGetRelid(rel), attnum); + (void) deleteDependencyRecordsFor(AttrDefaultRelationId, attrdefoid, false); + + /* Make above changes visible */ + CommandCounterIncrement(); + + /* + * Get rid of the GENERATED expression itself. We use RESTRICT here for + * safety, but at present we do not expect anything to depend on the + * expression. + */ + RemoveAttrDefault(RelationGetRelid(rel), attnum, DROP_RESTRICT, + false, false); + + /* Prepare to store the new expression, in the catalogs */ + rawEnt = (RawColumnDefault *) palloc(sizeof(RawColumnDefault)); + rawEnt->attnum = attnum; + rawEnt->raw_default = newExpr; + rawEnt->missingMode = false; + rawEnt->generated = ATTRIBUTE_GENERATED_STORED; + + /* Store the generated expression */ + AddRelationNewConstraints(rel, list_make1(rawEnt), NIL, + false, true, false, NULL); + + /* Make above new expression visible */ + CommandCounterIncrement(); + + /* Prepare for table rewrite */ + defval = (Expr *) build_column_default(rel, attnum); + + newval = (NewColumnValue *) palloc0(sizeof(NewColumnValue)); + newval->attnum = attnum; + newval->expr = expression_planner(defval); + newval->is_generated = true; + + tab->newvals = lappend(tab->newvals, newval); + tab->rewrite |= AT_REWRITE_DEFAULT_VAL; + + /* Drop any pg_statistic entry for the column */ + RemoveStatistics(RelationGetRelid(rel), attnum); + + InvokeObjectPostAlterHook(RelationRelationId, + RelationGetRelid(rel), attnum); + + ObjectAddressSubSet(address, RelationRelationId, + RelationGetRelid(rel), attnum); + return address; +} + +/* * ALTER TABLE ALTER COLUMN DROP EXPRESSION */ static void @@ -13300,7 +13430,7 @@ ATExecAlterColumnType(AlteredTableInfo *tab, Relation rel, * the info before executing ALTER TYPE, though, else the deparser will * get confused. */ - RememberAllDependentForRebuilding(tab, rel, attnum, colName); + RememberAllDependentForRebuilding(tab, AT_AlterColumnType, rel, attnum, colName); /* * Now scan for dependencies of this column on other things. The only @@ -13497,18 +13627,21 @@ ATExecAlterColumnType(AlteredTableInfo *tab, Relation rel, } /* - * Subroutine for ATExecAlterColumnType: Find everything that depends on the - * column (constraints, indexes, etc), and record enough information to let us - * recreate the objects. + * Subroutine for ATExecAlterColumnType and ATExecSetExpression: Find everything + * that depends on the column (constraints, indexes, etc), and record enough + * information to let us recreate the objects. */ static void -RememberAllDependentForRebuilding(AlteredTableInfo *tab, Relation rel, AttrNumber attnum, const char *colName) +RememberAllDependentForRebuilding(AlteredTableInfo *tab, AlterTableType subtype, + Relation rel, AttrNumber attnum, const char *colName) { Relation depRel; ScanKeyData key[3]; SysScanDesc scan; HeapTuple depTup; + Assert(subtype == AT_AlterColumnType || subtype == AT_SetExpression); + depRel = table_open(DependRelationId, RowExclusiveLock); ScanKeyInit(&key[0], @@ -13572,12 +13705,13 @@ RememberAllDependentForRebuilding(AlteredTableInfo *tab, Relation rel, AttrNumbe case OCLASS_REWRITE: /* XXX someday see if we can cope with revising views */ - ereport(ERROR, - (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), - errmsg("cannot alter type of a column used by a view or rule"), - errdetail("%s depends on column \"%s\"", - getObjectDescription(&foundObject, false), - colName))); + if (subtype == AT_AlterColumnType) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("cannot alter type of a column used by a view or rule"), + errdetail("%s depends on column \"%s\"", + getObjectDescription(&foundObject, false), + colName))); break; case OCLASS_TRIGGER: @@ -13591,12 +13725,13 @@ RememberAllDependentForRebuilding(AlteredTableInfo *tab, Relation rel, AttrNumbe * significant amount of new code. Since we can't easily tell * which case applies, we punt for both. FIXME someday. */ - ereport(ERROR, - (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), - errmsg("cannot alter type of a column used in a trigger definition"), - errdetail("%s depends on column \"%s\"", - getObjectDescription(&foundObject, false), - colName))); + if (subtype == AT_AlterColumnType) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("cannot alter type of a column used in a trigger definition"), + errdetail("%s depends on column \"%s\"", + getObjectDescription(&foundObject, false), + colName))); break; case OCLASS_POLICY: @@ -13609,12 +13744,13 @@ RememberAllDependentForRebuilding(AlteredTableInfo *tab, Relation rel, AttrNumbe * easy enough to remove and recreate the policy; still, FIXME * someday. */ - ereport(ERROR, - (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), - errmsg("cannot alter type of a column used in a policy definition"), - errdetail("%s depends on column \"%s\"", - getObjectDescription(&foundObject, false), - colName))); + if (subtype == AT_AlterColumnType) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("cannot alter type of a column used in a policy definition"), + errdetail("%s depends on column \"%s\"", + getObjectDescription(&foundObject, false), + colName))); break; case OCLASS_DEFAULT: @@ -13634,19 +13770,20 @@ RememberAllDependentForRebuilding(AlteredTableInfo *tab, Relation rel, AttrNumbe /* * This must be a reference from the expression of a * generated column elsewhere in the same table. - * Changing the type of a column that is used by a - * generated column is not allowed by SQL standard, so - * just punt for now. It might be doable with some - * thinking and effort. + * Changing the type/generated expression of a column + * that is used by a generated column is not allowed + * by SQL standard, so just punt for now. It might be + * doable with some thinking and effort. */ - ereport(ERROR, - (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), - errmsg("cannot alter type of a column used by a generated column"), - errdetail("Column \"%s\" is used by generated column \"%s\".", - colName, - get_attname(col.objectId, - col.objectSubId, - false)))); + if (subtype == AT_AlterColumnType) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("cannot alter type of a column used by a generated column"), + errdetail("Column \"%s\" is used by generated column \"%s\".", + colName, + get_attname(col.objectId, + col.objectSubId, + false)))); } break; } @@ -13863,11 +14000,11 @@ RememberStatisticsForRebuilding(Oid stxoid, AlteredTableInfo *tab) } /* - * Cleanup after we've finished all the ALTER TYPE operations for a - * particular relation. We have to drop and recreate all the indexes - * and constraints that depend on the altered columns. We do the - * actual dropping here, but re-creation is managed by adding work - * queue entries to do those steps later. + * Cleanup after we've finished all the ALTER TYPE or SET EXPRESSION + * operations for a particular relation. We have to drop and recreate all the + * indexes and constraints that depend on the altered columns. We do the + * actual dropping here, but re-creation is managed by adding work queue + * entries to do those steps later. */ static void ATPostAlterTypeCleanup(List **wqueue, AlteredTableInfo *tab, LOCKMODE lockmode) diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y index 746365027c2..6b88096e8e1 100644 --- a/src/backend/parser/gram.y +++ b/src/backend/parser/gram.y @@ -2417,6 +2417,16 @@ alter_table_cmd: n->name = $3; $$ = (Node *) n; } + /* ALTER TABLE <name> ALTER [COLUMN] <colname> SET EXPRESSION AS <expr> */ + | ALTER opt_column ColId SET EXPRESSION AS '(' a_expr ')' + { + AlterTableCmd *n = makeNode(AlterTableCmd); + + n->subtype = AT_SetExpression; + n->name = $3; + n->def = $8; + $$ = (Node *) n; + } /* ALTER TABLE <name> ALTER [COLUMN] <colname> DROP EXPRESSION */ | ALTER opt_column ColId DROP EXPRESSION { diff --git a/src/bin/psql/tab-complete.c b/src/bin/psql/tab-complete.c index 00770a0e6bc..09914165e42 100644 --- a/src/bin/psql/tab-complete.c +++ b/src/bin/psql/tab-complete.c @@ -2504,7 +2504,7 @@ psql_completion(const char *text, int start, int end) /* ALTER TABLE ALTER [COLUMN] <foo> SET */ else if (Matches("ALTER", "TABLE", MatchAny, "ALTER", "COLUMN", MatchAny, "SET") || Matches("ALTER", "TABLE", MatchAny, "ALTER", MatchAny, "SET")) - COMPLETE_WITH("(", "COMPRESSION", "DEFAULT", "GENERATED", "NOT NULL", "STATISTICS", "STORAGE", + COMPLETE_WITH("(", "COMPRESSION", "DEFAULT", "EXPRESSION", "GENERATED", "NOT NULL", "STATISTICS", "STORAGE", /* a subset of ALTER SEQUENCE options */ "INCREMENT", "MINVALUE", "MAXVALUE", "START", "NO", "CACHE", "CYCLE"); /* ALTER TABLE ALTER [COLUMN] <foo> SET ( */ @@ -2515,6 +2515,14 @@ psql_completion(const char *text, int start, int end) else if (Matches("ALTER", "TABLE", MatchAny, "ALTER", "COLUMN", MatchAny, "SET", "COMPRESSION") || Matches("ALTER", "TABLE", MatchAny, "ALTER", MatchAny, "SET", "COMPRESSION")) COMPLETE_WITH("DEFAULT", "PGLZ", "LZ4"); + /* ALTER TABLE ALTER [COLUMN] <foo> SET EXPRESSION */ + else if (Matches("ALTER", "TABLE", MatchAny, "ALTER", "COLUMN", MatchAny, "SET", "EXPRESSION") || + Matches("ALTER", "TABLE", MatchAny, "ALTER", MatchAny, "SET", "EXPRESSION")) + COMPLETE_WITH("AS"); + /* ALTER TABLE ALTER [COLUMN] <foo> SET EXPRESSION AS */ + else if (Matches("ALTER", "TABLE", MatchAny, "ALTER", "COLUMN", MatchAny, "SET", "EXPRESSION", "AS") || + Matches("ALTER", "TABLE", MatchAny, "ALTER", MatchAny, "SET", "EXPRESSION", "AS")) + COMPLETE_WITH("("); /* ALTER TABLE ALTER [COLUMN] <foo> SET GENERATED */ else if (Matches("ALTER", "TABLE", MatchAny, "ALTER", "COLUMN", MatchAny, "SET", "GENERATED") || Matches("ALTER", "TABLE", MatchAny, "ALTER", MatchAny, "SET", "GENERATED")) diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h index 1ee92aa7f0c..b3181f34aee 100644 --- a/src/include/nodes/parsenodes.h +++ b/src/include/nodes/parsenodes.h @@ -2192,6 +2192,7 @@ typedef enum AlterTableType AT_DropNotNull, /* alter column drop not null */ AT_SetNotNull, /* alter column set not null */ AT_SetAttNotNull, /* set attnotnull w/o a constraint */ + AT_SetExpression, /* alter column set expression */ AT_DropExpression, /* alter column drop expression */ AT_SetStatistics, /* alter column set statistics */ AT_SetOptions, /* alter column set ( options ) */ diff --git a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c index 0b98cc8d69d..48563b2cf01 100644 --- a/src/test/modules/test_ddl_deparse/test_ddl_deparse.c +++ b/src/test/modules/test_ddl_deparse/test_ddl_deparse.c @@ -132,6 +132,9 @@ get_altertable_subcmdinfo(PG_FUNCTION_ARGS) case AT_SetAttNotNull: strtype = "SET ATTNOTNULL"; break; + case AT_SetExpression: + strtype = "SET EXPRESSION"; + break; case AT_DropExpression: strtype = "DROP EXPRESSION"; break; diff --git a/src/test/regress/expected/generated.out b/src/test/regress/expected/generated.out index a2f38d0f50a..cfc7678088c 100644 --- a/src/test/regress/expected/generated.out +++ b/src/test/regress/expected/generated.out @@ -578,6 +578,9 @@ INSERT INTO gtest20 (a) VALUES (10); -- ok INSERT INTO gtest20 (a) VALUES (30); -- violates constraint ERROR: new row for relation "gtest20" violates check constraint "gtest20_b_check" DETAIL: Failing row contains (30, 60). +ALTER TABLE gtest20 ALTER COLUMN b SET EXPRESSION AS (a * 100); -- violates constraint +ERROR: check constraint "gtest20_b_check" of relation "gtest20" is violated by some row +ALTER TABLE gtest20 ALTER COLUMN b SET EXPRESSION AS (a * 3); -- ok CREATE TABLE gtest20a (a int PRIMARY KEY, b int GENERATED ALWAYS AS (a * 2) STORED); INSERT INTO gtest20a (a) VALUES (10); INSERT INTO gtest20a (a) VALUES (30); @@ -673,6 +676,47 @@ SELECT * FROM gtest22c WHERE a = 1 AND b > 0; 1 | 2 (1 row) +ALTER TABLE gtest22c ALTER COLUMN b SET EXPRESSION AS (a * 4); +ANALYZE gtest22c; +EXPLAIN (COSTS OFF) SELECT * FROM gtest22c WHERE b = 8; + QUERY PLAN +--------------------------------------------- + Index Scan using gtest22c_b_idx on gtest22c + Index Cond: (b = 8) +(2 rows) + +SELECT * FROM gtest22c WHERE b = 8; + a | b +---+--- + 2 | 8 +(1 row) + +EXPLAIN (COSTS OFF) SELECT * FROM gtest22c WHERE b * 3 = 12; + QUERY PLAN +------------------------------------------------ + Index Scan using gtest22c_expr_idx on gtest22c + Index Cond: ((b * 3) = 12) +(2 rows) + +SELECT * FROM gtest22c WHERE b * 3 = 12; + a | b +---+--- + 1 | 4 +(1 row) + +EXPLAIN (COSTS OFF) SELECT * FROM gtest22c WHERE a = 1 AND b > 0; + QUERY PLAN +------------------------------------------------ + Index Scan using gtest22c_pred_idx on gtest22c + Index Cond: (a = 1) +(2 rows) + +SELECT * FROM gtest22c WHERE a = 1 AND b > 0; + a | b +---+--- + 1 | 4 +(1 row) + RESET enable_seqscan; RESET enable_bitmapscan; -- foreign keys @@ -698,6 +742,10 @@ INSERT INTO gtest23b VALUES (1); -- ok INSERT INTO gtest23b VALUES (5); -- error ERROR: insert or update on table "gtest23b" violates foreign key constraint "gtest23b_b_fkey" DETAIL: Key (b)=(10) is not present in table "gtest23a". +ALTER TABLE gtest23b ALTER COLUMN b SET EXPRESSION AS (a * 5); -- error +ERROR: insert or update on table "gtest23b" violates foreign key constraint "gtest23b_b_fkey" +DETAIL: Key (b)=(5) is not present in table "gtest23a". +ALTER TABLE gtest23b ALTER COLUMN b SET EXPRESSION AS (a * 1); -- ok DROP TABLE gtest23b; DROP TABLE gtest23a; CREATE TABLE gtest23p (x int, y int GENERATED ALWAYS AS (x * 2) STORED, PRIMARY KEY (y)); @@ -785,30 +833,119 @@ Partition of: gtest_parent FOR VALUES FROM ('08-01-2016') TO ('09-01-2016') Partition of: gtest_parent FOR VALUES FROM ('09-01-2016') TO ('10-01-2016') INSERT INTO gtest_parent (f1, f2) VALUES ('2016-07-15', 1); -SELECT * FROM gtest_parent; - f1 | f2 | f3 -------------+----+---- - 07-15-2016 | 1 | 2 -(1 row) +INSERT INTO gtest_parent (f1, f2) VALUES ('2016-07-15', 2); +INSERT INTO gtest_parent (f1, f2) VALUES ('2016-08-15', 3); +SELECT tableoid::regclass, * FROM gtest_parent ORDER BY 1, 2, 3; + tableoid | f1 | f2 | f3 +--------------+------------+----+---- + gtest_child | 07-15-2016 | 1 | 2 + gtest_child | 07-15-2016 | 2 | 4 + gtest_child2 | 08-15-2016 | 3 | 66 +(3 rows) -SELECT * FROM gtest_child; - f1 | f2 | f3 -------------+----+---- - 07-15-2016 | 1 | 2 -(1 row) +UPDATE gtest_parent SET f1 = f1 + 60 WHERE f2 = 1; +SELECT tableoid::regclass, * FROM gtest_parent ORDER BY 1, 2, 3; + tableoid | f1 | f2 | f3 +--------------+------------+----+---- + gtest_child | 07-15-2016 | 2 | 4 + gtest_child2 | 08-15-2016 | 3 | 66 + gtest_child3 | 09-13-2016 | 1 | 33 +(3 rows) -UPDATE gtest_parent SET f1 = f1 + 60; -SELECT * FROM gtest_parent; - f1 | f2 | f3 -------------+----+---- - 09-13-2016 | 1 | 33 -(1 row) +-- alter only parent's and one child's generation expression +ALTER TABLE ONLY gtest_parent ALTER COLUMN f3 SET EXPRESSION AS (f2 * 4); +ALTER TABLE gtest_child ALTER COLUMN f3 SET EXPRESSION AS (f2 * 10); +\d gtest_parent + Partitioned table "public.gtest_parent" + Column | Type | Collation | Nullable | Default +--------+--------+-----------+----------+------------------------------------- + f1 | date | | not null | + f2 | bigint | | | + f3 | bigint | | | generated always as (f2 * 4) stored +Partition key: RANGE (f1) +Number of partitions: 3 (Use \d+ to list them.) -SELECT * FROM gtest_child3; - f1 | f2 | f3 -------------+----+---- - 09-13-2016 | 1 | 33 -(1 row) +\d gtest_child + Table "public.gtest_child" + Column | Type | Collation | Nullable | Default +--------+--------+-----------+----------+-------------------------------------- + f1 | date | | not null | + f2 | bigint | | | + f3 | bigint | | | generated always as (f2 * 10) stored +Partition of: gtest_parent FOR VALUES FROM ('07-01-2016') TO ('08-01-2016') + +\d gtest_child2 + Table "public.gtest_child2" + Column | Type | Collation | Nullable | Default +--------+--------+-----------+----------+-------------------------------------- + f1 | date | | not null | + f2 | bigint | | | + f3 | bigint | | | generated always as (f2 * 22) stored +Partition of: gtest_parent FOR VALUES FROM ('08-01-2016') TO ('09-01-2016') + +\d gtest_child3 + Table "public.gtest_child3" + Column | Type | Collation | Nullable | Default +--------+--------+-----------+----------+-------------------------------------- + f1 | date | | not null | + f2 | bigint | | | + f3 | bigint | | | generated always as (f2 * 33) stored +Partition of: gtest_parent FOR VALUES FROM ('09-01-2016') TO ('10-01-2016') + +SELECT tableoid::regclass, * FROM gtest_parent ORDER BY 1, 2, 3; + tableoid | f1 | f2 | f3 +--------------+------------+----+---- + gtest_child | 07-15-2016 | 2 | 20 + gtest_child2 | 08-15-2016 | 3 | 66 + gtest_child3 | 09-13-2016 | 1 | 33 +(3 rows) + +-- alter generation expression of parent and all its children altogether +ALTER TABLE gtest_parent ALTER COLUMN f3 SET EXPRESSION AS (f2 * 2); +\d gtest_parent + Partitioned table "public.gtest_parent" + Column | Type | Collation | Nullable | Default +--------+--------+-----------+----------+------------------------------------- + f1 | date | | not null | + f2 | bigint | | | + f3 | bigint | | | generated always as (f2 * 2) stored +Partition key: RANGE (f1) +Number of partitions: 3 (Use \d+ to list them.) + +\d gtest_child + Table "public.gtest_child" + Column | Type | Collation | Nullable | Default +--------+--------+-----------+----------+------------------------------------- + f1 | date | | not null | + f2 | bigint | | | + f3 | bigint | | | generated always as (f2 * 2) stored +Partition of: gtest_parent FOR VALUES FROM ('07-01-2016') TO ('08-01-2016') + +\d gtest_child2 + Table "public.gtest_child2" + Column | Type | Collation | Nullable | Default +--------+--------+-----------+----------+------------------------------------- + f1 | date | | not null | + f2 | bigint | | | + f3 | bigint | | | generated always as (f2 * 2) stored +Partition of: gtest_parent FOR VALUES FROM ('08-01-2016') TO ('09-01-2016') + +\d gtest_child3 + Table "public.gtest_child3" + Column | Type | Collation | Nullable | Default +--------+--------+-----------+----------+------------------------------------- + f1 | date | | not null | + f2 | bigint | | | + f3 | bigint | | | generated always as (f2 * 2) stored +Partition of: gtest_parent FOR VALUES FROM ('09-01-2016') TO ('10-01-2016') + +SELECT tableoid::regclass, * FROM gtest_parent ORDER BY 1, 2, 3; + tableoid | f1 | f2 | f3 +--------------+------------+----+---- + gtest_child | 07-15-2016 | 2 | 4 + gtest_child2 | 08-15-2016 | 3 | 6 + gtest_child3 | 09-13-2016 | 1 | 2 +(3 rows) -- we leave these tables around for purposes of testing dump/reload/upgrade -- generated columns in partition key (not allowed) @@ -825,7 +962,7 @@ DETAIL: Column "f3" is a generated column. -- ALTER TABLE ... ADD COLUMN CREATE TABLE gtest25 (a int PRIMARY KEY); INSERT INTO gtest25 VALUES (3), (4); -ALTER TABLE gtest25 ADD COLUMN b int GENERATED ALWAYS AS (a * 3) STORED; +ALTER TABLE gtest25 ADD COLUMN b int GENERATED ALWAYS AS (a * 2) STORED, ALTER COLUMN b SET EXPRESSION AS (a * 3); SELECT * FROM gtest25 ORDER BY a; a | b ---+---- @@ -935,18 +1072,50 @@ CREATE TABLE gtest29 ( b int GENERATED ALWAYS AS (a * 2) STORED ); INSERT INTO gtest29 (a) VALUES (3), (4); +SELECT * FROM gtest29; + a | b +---+--- + 3 | 6 + 4 | 8 +(2 rows) + +\d gtest29 + Table "public.gtest29" + Column | Type | Collation | Nullable | Default +--------+---------+-----------+----------+------------------------------------ + a | integer | | | + b | integer | | | generated always as (a * 2) stored + +ALTER TABLE gtest29 ALTER COLUMN a SET EXPRESSION AS (a * 3); -- error +ERROR: column "a" of relation "gtest29" is not a generated column ALTER TABLE gtest29 ALTER COLUMN a DROP EXPRESSION; -- error ERROR: column "a" of relation "gtest29" is not a stored generated column ALTER TABLE gtest29 ALTER COLUMN a DROP EXPRESSION IF EXISTS; -- notice NOTICE: column "a" of relation "gtest29" is not a stored generated column, skipping +-- Change the expression +ALTER TABLE gtest29 ALTER COLUMN b SET EXPRESSION AS (a * 3); +SELECT * FROM gtest29; + a | b +---+---- + 3 | 9 + 4 | 12 +(2 rows) + +\d gtest29 + Table "public.gtest29" + Column | Type | Collation | Nullable | Default +--------+---------+-----------+----------+------------------------------------ + a | integer | | | + b | integer | | | generated always as (a * 3) stored + ALTER TABLE gtest29 ALTER COLUMN b DROP EXPRESSION; INSERT INTO gtest29 (a) VALUES (5); INSERT INTO gtest29 (a, b) VALUES (6, 66); SELECT * FROM gtest29; a | b ---+---- - 3 | 6 - 4 | 8 + 3 | 9 + 4 | 12 5 | 6 | 66 (4 rows) diff --git a/src/test/regress/sql/generated.sql b/src/test/regress/sql/generated.sql index 298f6b3aa8b..cb55d77821f 100644 --- a/src/test/regress/sql/generated.sql +++ b/src/test/regress/sql/generated.sql @@ -293,6 +293,9 @@ CREATE TABLE gtest20 (a int PRIMARY KEY, b int GENERATED ALWAYS AS (a * 2) STORE INSERT INTO gtest20 (a) VALUES (10); -- ok INSERT INTO gtest20 (a) VALUES (30); -- violates constraint +ALTER TABLE gtest20 ALTER COLUMN b SET EXPRESSION AS (a * 100); -- violates constraint +ALTER TABLE gtest20 ALTER COLUMN b SET EXPRESSION AS (a * 3); -- ok + CREATE TABLE gtest20a (a int PRIMARY KEY, b int GENERATED ALWAYS AS (a * 2) STORED); INSERT INTO gtest20a (a) VALUES (10); INSERT INTO gtest20a (a) VALUES (30); @@ -341,6 +344,15 @@ EXPLAIN (COSTS OFF) SELECT * FROM gtest22c WHERE b * 3 = 6; SELECT * FROM gtest22c WHERE b * 3 = 6; EXPLAIN (COSTS OFF) SELECT * FROM gtest22c WHERE a = 1 AND b > 0; SELECT * FROM gtest22c WHERE a = 1 AND b > 0; + +ALTER TABLE gtest22c ALTER COLUMN b SET EXPRESSION AS (a * 4); +ANALYZE gtest22c; +EXPLAIN (COSTS OFF) SELECT * FROM gtest22c WHERE b = 8; +SELECT * FROM gtest22c WHERE b = 8; +EXPLAIN (COSTS OFF) SELECT * FROM gtest22c WHERE b * 3 = 12; +SELECT * FROM gtest22c WHERE b * 3 = 12; +EXPLAIN (COSTS OFF) SELECT * FROM gtest22c WHERE a = 1 AND b > 0; +SELECT * FROM gtest22c WHERE a = 1 AND b > 0; RESET enable_seqscan; RESET enable_bitmapscan; @@ -356,6 +368,8 @@ CREATE TABLE gtest23b (a int PRIMARY KEY, b int GENERATED ALWAYS AS (a * 2) STOR INSERT INTO gtest23b VALUES (1); -- ok INSERT INTO gtest23b VALUES (5); -- error +ALTER TABLE gtest23b ALTER COLUMN b SET EXPRESSION AS (a * 5); -- error +ALTER TABLE gtest23b ALTER COLUMN b SET EXPRESSION AS (a * 1); -- ok DROP TABLE gtest23b; DROP TABLE gtest23a; @@ -414,11 +428,28 @@ ALTER TABLE gtest_parent ATTACH PARTITION gtest_child3 FOR VALUES FROM ('2016-09 \d gtest_child2 \d gtest_child3 INSERT INTO gtest_parent (f1, f2) VALUES ('2016-07-15', 1); -SELECT * FROM gtest_parent; -SELECT * FROM gtest_child; -UPDATE gtest_parent SET f1 = f1 + 60; -SELECT * FROM gtest_parent; -SELECT * FROM gtest_child3; +INSERT INTO gtest_parent (f1, f2) VALUES ('2016-07-15', 2); +INSERT INTO gtest_parent (f1, f2) VALUES ('2016-08-15', 3); +SELECT tableoid::regclass, * FROM gtest_parent ORDER BY 1, 2, 3; +UPDATE gtest_parent SET f1 = f1 + 60 WHERE f2 = 1; +SELECT tableoid::regclass, * FROM gtest_parent ORDER BY 1, 2, 3; + +-- alter only parent's and one child's generation expression +ALTER TABLE ONLY gtest_parent ALTER COLUMN f3 SET EXPRESSION AS (f2 * 4); +ALTER TABLE gtest_child ALTER COLUMN f3 SET EXPRESSION AS (f2 * 10); +\d gtest_parent +\d gtest_child +\d gtest_child2 +\d gtest_child3 +SELECT tableoid::regclass, * FROM gtest_parent ORDER BY 1, 2, 3; + +-- alter generation expression of parent and all its children altogether +ALTER TABLE gtest_parent ALTER COLUMN f3 SET EXPRESSION AS (f2 * 2); +\d gtest_parent +\d gtest_child +\d gtest_child2 +\d gtest_child3 +SELECT tableoid::regclass, * FROM gtest_parent ORDER BY 1, 2, 3; -- we leave these tables around for purposes of testing dump/reload/upgrade -- generated columns in partition key (not allowed) @@ -428,7 +459,7 @@ CREATE TABLE gtest_part_key (f1 date NOT NULL, f2 bigint, f3 bigint GENERATED AL -- ALTER TABLE ... ADD COLUMN CREATE TABLE gtest25 (a int PRIMARY KEY); INSERT INTO gtest25 VALUES (3), (4); -ALTER TABLE gtest25 ADD COLUMN b int GENERATED ALWAYS AS (a * 3) STORED; +ALTER TABLE gtest25 ADD COLUMN b int GENERATED ALWAYS AS (a * 2) STORED, ALTER COLUMN b SET EXPRESSION AS (a * 3); SELECT * FROM gtest25 ORDER BY a; ALTER TABLE gtest25 ADD COLUMN x int GENERATED ALWAYS AS (b * 4) STORED; -- error ALTER TABLE gtest25 ADD COLUMN x int GENERATED ALWAYS AS (z * 4) STORED; -- error @@ -473,8 +504,17 @@ CREATE TABLE gtest29 ( b int GENERATED ALWAYS AS (a * 2) STORED ); INSERT INTO gtest29 (a) VALUES (3), (4); +SELECT * FROM gtest29; +\d gtest29 +ALTER TABLE gtest29 ALTER COLUMN a SET EXPRESSION AS (a * 3); -- error ALTER TABLE gtest29 ALTER COLUMN a DROP EXPRESSION; -- error ALTER TABLE gtest29 ALTER COLUMN a DROP EXPRESSION IF EXISTS; -- notice + +-- Change the expression +ALTER TABLE gtest29 ALTER COLUMN b SET EXPRESSION AS (a * 3); +SELECT * FROM gtest29; +\d gtest29 + ALTER TABLE gtest29 ALTER COLUMN b DROP EXPRESSION; INSERT INTO gtest29 (a) VALUES (5); INSERT INTO gtest29 (a, b) VALUES (6, 66); |