From 08023c65c80527f119ca12368f43822f0cdc3b19 Mon Sep 17 00:00:00 2001
From: "Chao Li (Evan)" <lic@highgo.com>
Date: Tue, 21 Oct 2025 14:28:48 +0800
Subject: [PATCH v2] Alow ALTER COLUMN TYPE when dependent generated column has
 SET EXPRESSION
MIME-Version: 1.0
Content-Type: text/plain; charset=UTF-8
Content-Transfer-Encoding: 8bit

Previously, altering the type of a column that is referenced by a
generated column would fail, because changing the base column’s
type could invalidate the generated column’s expression.

With this patch, if the ALTER TABLE command also provides a SET
EXPRESSION clause for the dependent generated column, the type
change is allowed. This ensures that the generated column can be
safely updated to reflect the new base column type within the
same statement.

Example:

-- Before this patch, the recommended usage was:
ALTER TABLE gtest
  DROP COLUMN x,
  ALTER COLUMN a TYPE float8,
  ADD COLUMN x bigint GENERATED ALWAYS AS ((a::int + b) * 2) STORED;

-- With this patch, the statement is simplified as:
ALTER TABLE gtest
  ALTER COLUMN a TYPE float8,
  ALTER COLUMN x SET EXPRESSION ((a::int + b) * 2);

Author: Chao Li <lic@highgo.com>
Discussion: https://postgr.es/m/A61F14F6-339D-46EF-9FC1-A8438FE3BE86@gmail.com
---
 src/backend/commands/tablecmds.c              | 51 +++++++++++++++----
 .../regress/expected/generated_stored.out     | 37 ++++++++++++--
 .../regress/expected/generated_virtual.out    | 37 ++++++++++++--
 src/test/regress/sql/generated_stored.sql     | 13 +++++
 src/test/regress/sql/generated_virtual.sql    | 13 +++++
 5 files changed, 130 insertions(+), 21 deletions(-)

diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 5fd8b51312c..95123e0fdbb 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -739,7 +739,7 @@ static List *GetParentedForeignKeyRefs(Relation partition);
 static void ATDetachCheckNoForeignKeyRefs(Relation partition);
 static char GetAttributeCompression(Oid atttypid, const char *compression);
 static char GetAttributeStorage(Oid atttypid, const char *storagemode);
-
+static bool ColumnHasSetExpression(const AlteredTableInfo *tab, const char *colname);
 
 /* ----------------------------------------------------------------
  *		DefineRelation
@@ -15172,18 +15172,27 @@ RememberAllDependentForRebuilding(AlteredTableInfo *tab, AlterTableType subtype,
 						 * generated column elsewhere in the same table.
 						 * 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.
+						 * by SQL standard, so just punt for now. However, if
+						 * the generated column has a SET EXPRESSION, then we
+						 * can allow the column type change.
 						 */
 						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))));
+						{
+							const char *genColName;
+
+							Assert(rel->rd_rel->oid == col.objectId);
+							genColName = get_attname(col.objectId,
+													 col.objectSubId,
+													 false);
+
+							if (!ColumnHasSetExpression(tab, genColName))
+								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,
+												   genColName)));
+						}
 					}
 					break;
 				}
@@ -22012,3 +22021,23 @@ GetAttributeStorage(Oid atttypid, const char *storagemode)
 
 	return cstorage;
 }
+
+/*
+ * Check if column has set expression in the ALTER TABLE command.
+ */
+static bool
+ColumnHasSetExpression(const AlteredTableInfo *tab, const char *colname)
+{
+	ListCell   *lc;
+
+	foreach(lc, tab->subcmds[AT_PASS_SET_EXPRESSION])
+	{
+		AlterTableCmd *cmd = (AlterTableCmd *) lfirst(lc);
+
+		if (strcmp(cmd->name, colname) == 0)
+		{
+			return true;
+		}
+	}
+	return false;
+}
diff --git a/src/test/regress/expected/generated_stored.out b/src/test/regress/expected/generated_stored.out
index adac2cedfb2..33751462eca 100644
--- a/src/test/regress/expected/generated_stored.out
+++ b/src/test/regress/expected/generated_stored.out
@@ -1168,12 +1168,12 @@ ALTER TABLE gtest27
  b      | bigint |           |          | 
  x      | bigint |           |          | generated always as ((a + b) * 2) stored
 
--- Ideally you could just do this, but not today (and should x change type?):
+-- Also possible this way:
 ALTER TABLE gtest27
-  ALTER COLUMN a TYPE float8,
-  ALTER COLUMN b TYPE float8;  -- error
-ERROR:  cannot alter type of a column used by a generated column
-DETAIL:  Column "a" is used by generated column "x".
+  ALTER COLUMN a TYPE bigint,
+  ALTER COLUMN b TYPE bigint,
+  ALTER COLUMN x TYPE bigint,
+  ALTER COLUMN x SET EXPRESSION AS ((a + b) * 2);
 \d gtest27
                       Table "generated_stored_tests.gtest27"
  Column |  Type  | Collation | Nullable |                 Default                  
@@ -1182,6 +1182,33 @@ DETAIL:  Column "a" is used by generated column "x".
  b      | bigint |           |          | 
  x      | bigint |           |          | generated always as ((a + b) * 2) stored
 
+-- So, you can change a column's type as long as any dependent generated
+-- column already has a set expression defined:
+ALTER TABLE gtest27
+  ALTER COLUMN a TYPE float8,
+  ALTER COLUMN x SET EXPRESSION AS ((a::int + b) * 2);
+\d gtest27
+                                Table "generated_stored_tests.gtest27"
+ Column |       Type       | Collation | Nullable |                      Default                      
+--------+------------------+-----------+----------+---------------------------------------------------
+ a      | double precision |           |          | 
+ b      | bigint           |           |          | 
+ x      | bigint           |           |          | generated always as ((a::integer + b) * 2) stored
+
+-- Ideally you could just do this, but not today (and should x change type?):
+ALTER TABLE gtest27
+  ALTER COLUMN a TYPE float8,
+  ALTER COLUMN b TYPE float8;  -- error
+ERROR:  cannot alter type of a column used by a generated column
+DETAIL:  Column "a" is used by generated column "x".
+\d gtest27
+                                Table "generated_stored_tests.gtest27"
+ Column |       Type       | Collation | Nullable |                      Default                      
+--------+------------------+-----------+----------+---------------------------------------------------
+ a      | double precision |           |          | 
+ b      | bigint           |           |          | 
+ x      | bigint           |           |          | generated always as ((a::integer + b) * 2) stored
+
 SELECT * FROM gtest27;
  a | b  | x  
 ---+----+----
diff --git a/src/test/regress/expected/generated_virtual.out b/src/test/regress/expected/generated_virtual.out
index c861bd36c5a..95f0bc17897 100644
--- a/src/test/regress/expected/generated_virtual.out
+++ b/src/test/regress/expected/generated_virtual.out
@@ -1138,12 +1138,12 @@ ALTER TABLE gtest27
  b      | bigint |           |          | 
  x      | bigint |           |          | generated always as ((a + b) * 2)
 
--- Ideally you could just do this, but not today (and should x change type?):
+-- Also possible this way:
 ALTER TABLE gtest27
-  ALTER COLUMN a TYPE float8,
-  ALTER COLUMN b TYPE float8;  -- error
-ERROR:  cannot alter type of a column used by a generated column
-DETAIL:  Column "a" is used by generated column "x".
+  ALTER COLUMN a TYPE bigint,
+  ALTER COLUMN b TYPE bigint,
+  ALTER COLUMN x TYPE bigint,
+  ALTER COLUMN x SET EXPRESSION AS ((a + b) * 2);
 \d gtest27
                   Table "generated_virtual_tests.gtest27"
  Column |  Type  | Collation | Nullable |              Default              
@@ -1152,6 +1152,33 @@ DETAIL:  Column "a" is used by generated column "x".
  b      | bigint |           |          | 
  x      | bigint |           |          | generated always as ((a + b) * 2)
 
+-- So, you can change a column's type as long as any dependent generated
+-- column already has a set expression defined:
+ALTER TABLE gtest27
+  ALTER COLUMN a TYPE float8,
+  ALTER COLUMN x SET EXPRESSION AS ((a::int + b) * 2);
+\d gtest27
+                            Table "generated_virtual_tests.gtest27"
+ Column |       Type       | Collation | Nullable |                  Default                   
+--------+------------------+-----------+----------+--------------------------------------------
+ a      | double precision |           |          | 
+ b      | bigint           |           |          | 
+ x      | bigint           |           |          | generated always as ((a::integer + b) * 2)
+
+-- Ideally you could just do this, but not today (and should x change type?):
+ALTER TABLE gtest27
+  ALTER COLUMN a TYPE float8,
+  ALTER COLUMN b TYPE float8;  -- error
+ERROR:  cannot alter type of a column used by a generated column
+DETAIL:  Column "a" is used by generated column "x".
+\d gtest27
+                            Table "generated_virtual_tests.gtest27"
+ Column |       Type       | Collation | Nullable |                  Default                   
+--------+------------------+-----------+----------+--------------------------------------------
+ a      | double precision |           |          | 
+ b      | bigint           |           |          | 
+ x      | bigint           |           |          | generated always as ((a::integer + b) * 2)
+
 SELECT * FROM gtest27;
  a | b  | x  
 ---+----+----
diff --git a/src/test/regress/sql/generated_stored.sql b/src/test/regress/sql/generated_stored.sql
index f56fde8d4e5..4e2d0f9178d 100644
--- a/src/test/regress/sql/generated_stored.sql
+++ b/src/test/regress/sql/generated_stored.sql
@@ -537,6 +537,19 @@ ALTER TABLE gtest27
   ALTER COLUMN b TYPE bigint,
   ADD COLUMN x bigint GENERATED ALWAYS AS ((a + b) * 2) STORED;
 \d gtest27
+-- Also possible this way:
+ALTER TABLE gtest27
+  ALTER COLUMN a TYPE bigint,
+  ALTER COLUMN b TYPE bigint,
+  ALTER COLUMN x TYPE bigint,
+  ALTER COLUMN x SET EXPRESSION AS ((a + b) * 2);
+\d gtest27
+-- So, you can change a column's type as long as any dependent generated
+-- column already has a set expression defined:
+ALTER TABLE gtest27
+  ALTER COLUMN a TYPE float8,
+  ALTER COLUMN x SET EXPRESSION AS ((a::int + b) * 2);
+\d gtest27
 -- Ideally you could just do this, but not today (and should x change type?):
 ALTER TABLE gtest27
   ALTER COLUMN a TYPE float8,
diff --git a/src/test/regress/sql/generated_virtual.sql b/src/test/regress/sql/generated_virtual.sql
index adfe88d74ae..c04b48ec86f 100644
--- a/src/test/regress/sql/generated_virtual.sql
+++ b/src/test/regress/sql/generated_virtual.sql
@@ -588,6 +588,19 @@ ALTER TABLE gtest27
   ALTER COLUMN b TYPE bigint,
   ADD COLUMN x bigint GENERATED ALWAYS AS ((a + b) * 2) VIRTUAL;
 \d gtest27
+-- Also possible this way:
+ALTER TABLE gtest27
+  ALTER COLUMN a TYPE bigint,
+  ALTER COLUMN b TYPE bigint,
+  ALTER COLUMN x TYPE bigint,
+  ALTER COLUMN x SET EXPRESSION AS ((a + b) * 2);
+\d gtest27
+-- So, you can change a column's type as long as any dependent generated
+-- column already has a set expression defined:
+ALTER TABLE gtest27
+  ALTER COLUMN a TYPE float8,
+  ALTER COLUMN x SET EXPRESSION AS ((a::int + b) * 2);
+\d gtest27
 -- Ideally you could just do this, but not today (and should x change type?):
 ALTER TABLE gtest27
   ALTER COLUMN a TYPE float8,
-- 
2.39.5 (Apple Git-154)

