hi.

CREATE FUNCTION dummy_trigger() RETURNS TRIGGER AS $$
  BEGIN
    RETURN NULL;
  END
$$ language plpgsql;

create table main_table(a int);
CREATE TRIGGER before_ins_stmt_trig BEFORE INSERT ON main_table
FOR EACH ROW
WHEN (new.a > 0)
EXECUTE PROCEDURE dummy_trigger();

ALTER TABLE main_table ALTER COLUMN a SET DATA TYPE INT8; --error
ALTER TABLE main_table DROP COLUMN a; --error

Dropping a column or changing its data type will fail if the column is
referenced in a trigger’s WHEN clause, that's the current behavior.
I think we should expand that to a whole-row reference WHEN clause in trigger.

DROP TRIGGER before_ins_stmt_trig ON main_table;
CREATE TRIGGER before_ins_stmt_trig BEFORE INSERT ON main_table
FOR EACH ROW
WHEN (new is null)
EXECUTE PROCEDURE dummy_trigger();
ALTER TABLE main_table ALTER COLUMN a SET DATA TYPE INT8; --expect to error
ALTER TABLE main_table DROP COLUMN a;  --expect to error

new summary:
For (constraints, indexes, policies, triggers) that contain whole-row
references:
ALTER TABLE DROP COLUMN [CASCADE] will drop these objects too.

ALTER COLUMN SET DATA TYPE will error out because whole-row–dependent objects
exist.



--
jian
https://www.enterprisedb.com/
From 2069af2a2ea79eec7156a6fe373efaa6e5a8b372 Mon Sep 17 00:00:00 2001
From: jian he <[email protected]>
Date: Fri, 26 Dec 2025 11:08:13 +0800
Subject: [PATCH v7 1/3] fix DDL wholerow referenced constraints and indexes
MIME-Version: 1.0
Content-Type: text/plain; charset=UTF-8
Content-Transfer-Encoding: 8bit

1. ALTER TABLE DROP COLUMN.
ALTER TABLE DROP COLUMN should remove indexes or constraints contain
whole-row expression.
We enumerate all constraints and indexes and check one by one to determine
whether it contains a whole-row Var reference. If such a reference is found, we
record the dependency and later performMultipleDeletions will drop it.

for example:
CREATE TABLE ts (a int, constraint cc check((ts = ROW(1))));
CREATE INDEX tsi3 on ts ((ts is null));
ALTER TABLE DROP COLUMN should drop above all indexes, constraints on table ts.

2. ALTER COLUMN SET DATA TYPE
ALTER COLUMN SET DATA TYPE should error out when whole-row referenced object
(index, constraints, etc) exists.
ALTER COLUMN SET DATA TYPE fundamentally changes the table’s record type; At
present, we cannot compare records that contain columns of dissimilar types, see
function record_eq.  As a result, ALTER COLUMN SET DATA TYPE does not work for
whole-row reference objects (such as constraints and indexes), and must
therefore raise an error.

For example, below ALTER COLUMN SET DATA TYPE should fail.
CREATE TABLE ts (a int, CONSTRAINT cc CHECK ((ts = ROW(1))));
CREATE INDEX ON ts ((ts IS NOT NULL));
ALTER TABLE ts ALTER COLUMN a SET DATA TYPE int8;

discussion: https://postgr.es/m/CACJufxGA6KVQy7DbHGLVw9s9KKmpGyZt5ME6C7kEfjDpr2wZCw@mail.gmail.com
commitfest: https://commitfest.postgresql.org/patch/6055
---
 src/backend/commands/tablecmds.c          | 228 +++++++++++++++++++++-
 src/test/regress/expected/constraints.out |  21 ++
 src/test/regress/expected/indexing.out    |  35 ++++
 src/test/regress/sql/constraints.sql      |  16 ++
 src/test/regress/sql/indexing.sql         |  20 ++
 5 files changed, 317 insertions(+), 3 deletions(-)

diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 1d9565b09fc..714ab75e7b3 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -745,6 +745,9 @@ static void ATExecMergePartitions(List **wqueue, AlteredTableInfo *tab, Relation
 static void ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab,
 								 Relation rel, PartitionCmd *cmd,
 								 AlterTableUtilityContext *context);
+static void recordWholeRowDependencyOnOrError(Relation rel,
+											  const ObjectAddress *object,
+											  bool error_out);
 
 /* ----------------------------------------------------------------
  *		DefineRelation
@@ -9393,6 +9396,21 @@ ATExecDropColumn(List **wqueue, Relation rel, const char *colName,
 
 	ReleaseSysCache(tuple);
 
+	object.classId = RelationRelationId;
+	object.objectId = RelationGetRelid(rel);
+	object.objectSubId = attnum;
+
+	/*
+	 * We should also remove indexes or constraints that contain whole-row
+	 * expression. Using recordWholeRowDependencyOnOrError to establish a
+	 * dependency between the column and any constraint or index involving
+	 * whole-row Vars.  performMultipleDeletions will then take care of
+	 * removing them later.
+	 */
+	recordWholeRowDependencyOnOrError(rel, &object, false);
+
+	CommandCounterIncrement();
+
 	/*
 	 * Propagate to children as appropriate.  Unlike most other ALTER
 	 * routines, we have to do this one level of recursion at a time; we can't
@@ -9486,9 +9504,6 @@ ATExecDropColumn(List **wqueue, Relation rel, const char *colName,
 	}
 
 	/* Add object to delete */
-	object.classId = RelationRelationId;
-	object.objectId = RelationGetRelid(rel);
-	object.objectSubId = attnum;
 	add_exact_object_address(&object, addrs);
 
 	if (!recursing)
@@ -14773,6 +14788,7 @@ ATExecAlterColumnType(AlteredTableInfo *tab, Relation rel,
 	SysScanDesc scan;
 	HeapTuple	depTup;
 	ObjectAddress address;
+	ObjectAddress object;
 
 	/*
 	 * Clear all the missing values if we're rewriting the table, since this
@@ -14868,6 +14884,16 @@ ATExecAlterColumnType(AlteredTableInfo *tab, Relation rel,
 	 */
 	RememberAllDependentForRebuilding(tab, AT_AlterColumnType, rel, attnum, colName);
 
+	object.classId = RelationRelationId;
+	object.objectId = RelationGetRelid(rel);
+	object.objectSubId = attnum;
+
+	/*
+	 * Check for whole-row referenced objects (constraints, indexes etc) --
+	 * can't cope
+	 */
+	recordWholeRowDependencyOnOrError(rel, &object, true);
+
 	/*
 	 * Now scan for dependencies of this column on other things.  The only
 	 * things we should find are the dependency on the column datatype and
@@ -23337,3 +23363,199 @@ ATExecSplitPartition(List **wqueue, AlteredTableInfo *tab, Relation rel,
 	/* Restore the userid and security context. */
 	SetUserIdAndSecContext(save_userid, save_sec_context);
 }
+
+static void
+recordDependencyOnOrError(Relation rel, const ObjectAddress *depender,
+						  const ObjectAddress *referenced, bool error_out,
+						  DependencyType behavior)
+{
+	if (error_out)
+		ereport(ERROR,
+				errcode(ERRCODE_DATATYPE_MISMATCH),
+				errmsg("cannot alter table \"%s\" because %s uses its row type",
+					   RelationGetRelationName(rel),
+					   getObjectDescription(depender, false)),
+				errhint("You might need to drop %s first",
+						getObjectDescription(depender, false)));
+	else
+		recordDependencyOn(depender, referenced, behavior);
+}
+
+/*
+ * Record dependencies between whole-row objects (indexes, CHECK constraints, etc)
+ * and the relation's ObjectAddress.
+ *
+ * error_out means can not install such dependency, we need error out explicitly.
+ */
+static void
+recordWholeRowDependencyOnOrError(Relation rel, const ObjectAddress *object,
+								  bool error_out)
+{
+	Node	   *expr = NULL;
+	ScanKeyData skey;
+	Relation	pg_index;
+	SysScanDesc indscan;
+	HeapTuple	htup;
+	HeapTuple	indexTuple;
+	List	   *indexlist = NIL;
+	Bitmapset  *expr_attrs = NULL;
+	Datum		exprDatum;
+	char	   *exprString;
+	bool		isnull;
+	bool		find_wholerow = false;
+	TupleConstr *constr = RelationGetDescr(rel)->constr;
+
+	/*
+	 * Loop through each CHECK constraint, see if it contain whole-row
+	 * references or not
+	 */
+	if (constr && constr->num_check > 0)
+	{
+		Relation	pg_constraint;
+		SysScanDesc conscan;
+		ObjectAddress con_obj;
+
+		pg_constraint = table_open(ConstraintRelationId, AccessShareLock);
+
+		/* Search pg_constraint for relevant entries */
+		ScanKeyInit(&skey,
+					Anum_pg_constraint_conrelid,
+					BTEqualStrategyNumber, F_OIDEQ,
+					ObjectIdGetDatum(RelationGetRelid(rel)));
+
+		conscan = systable_beginscan(pg_constraint, ConstraintRelidTypidNameIndexId, true,
+									 NULL, 1, &skey);
+		while (HeapTupleIsValid(htup = systable_getnext(conscan)))
+		{
+			Form_pg_constraint conform = (Form_pg_constraint) GETSTRUCT(htup);
+
+			if (conform->contype != CONSTRAINT_CHECK)
+				continue;
+
+			/* Grab and test conbin is actually set */
+			exprDatum = fastgetattr(htup,
+									Anum_pg_constraint_conbin,
+									RelationGetDescr(pg_constraint), &isnull);
+			if (isnull)
+				elog(WARNING, "null conbin for relation \"%s\"",
+					 RelationGetRelationName(rel));
+			else
+			{
+				char	   *s = TextDatumGetCString(exprDatum);
+
+				expr = stringToNode(s);
+				pfree(s);
+
+				/* Find all attributes referenced */
+				pull_varattnos(expr, 1, &expr_attrs);
+
+				find_wholerow = bms_is_member(0 - FirstLowInvalidHeapAttributeNumber,
+											  expr_attrs);
+
+				if (find_wholerow)
+				{
+					con_obj.classId = ConstraintRelationId;
+					con_obj.objectId = conform->oid;
+					con_obj.objectSubId = 0;
+
+					recordDependencyOnOrError(rel, &con_obj, object, error_out,
+											  DEPENDENCY_AUTO);
+				}
+			}
+		}
+		systable_endscan(conscan);
+		table_close(pg_constraint, AccessShareLock);
+	}
+
+	/* now checking index whole-row references */
+	/* Prepare to scan pg_index for entries having indrelid = this rel */
+	ScanKeyInit(&skey,
+				Anum_pg_index_indrelid,
+				BTEqualStrategyNumber, F_OIDEQ,
+				ObjectIdGetDatum(RelationGetRelid(rel)));
+
+	pg_index = table_open(IndexRelationId, AccessShareLock);
+
+	indscan = systable_beginscan(pg_index, IndexIndrelidIndexId, true,
+								 NULL, 1, &skey);
+	while (HeapTupleIsValid(htup = systable_getnext(indscan)))
+	{
+		Form_pg_index index = (Form_pg_index) GETSTRUCT(htup);
+
+		/* add index's OID to result list */
+		indexlist = lappend_oid(indexlist, index->indexrelid);
+	}
+	systable_endscan(indscan);
+
+	table_close(pg_index, AccessShareLock);
+
+	foreach_oid(indexoid, indexlist)
+	{
+		ObjectAddress idx_obj;
+		Form_pg_index indexStruct;
+
+		indexTuple = SearchSysCache1(INDEXRELID, ObjectIdGetDatum(indexoid));
+
+		if (!HeapTupleIsValid(indexTuple))
+			elog(ERROR, "cache lookup failed for index %u", indexoid);
+		indexStruct = (Form_pg_index) GETSTRUCT(indexTuple);
+
+		if (!heap_attisnull(indexTuple, Anum_pg_index_indexprs, NULL))
+		{
+			expr_attrs = NULL;
+
+			/* Convert text string to node tree */
+			exprDatum = SysCacheGetAttrNotNull(INDEXRELID, indexTuple,
+											   Anum_pg_index_indexprs);
+			exprString = TextDatumGetCString(exprDatum);
+			expr = (Node *) stringToNode(exprString);
+			pfree(exprString);
+
+			pull_varattnos(expr, 1, &expr_attrs);
+
+			find_wholerow = bms_is_member(0 - FirstLowInvalidHeapAttributeNumber,
+										  expr_attrs);
+
+			if (find_wholerow)
+			{
+				idx_obj.classId = RelationRelationId;
+				idx_obj.objectId = indexStruct->indexrelid;
+				idx_obj.objectSubId = 0;
+
+				recordDependencyOnOrError(rel, &idx_obj, object, error_out,
+										  DEPENDENCY_AUTO);
+
+				ReleaseSysCache(indexTuple);
+
+				continue;
+			}
+		}
+
+		if (!heap_attisnull(indexTuple, Anum_pg_index_indpred, NULL))
+		{
+			expr_attrs = NULL;
+
+			/* Convert text string to node tree */
+			exprDatum = SysCacheGetAttrNotNull(INDEXRELID, indexTuple,
+											   Anum_pg_index_indpred);
+			exprString = TextDatumGetCString(exprDatum);
+			expr = (Node *) stringToNode(exprString);
+			pfree(exprString);
+
+			pull_varattnos(expr, 1, &expr_attrs);
+
+			find_wholerow = bms_is_member(0 - FirstLowInvalidHeapAttributeNumber,
+										  expr_attrs);
+			if (find_wholerow)
+			{
+				idx_obj.classId = RelationRelationId;
+				idx_obj.objectId = indexStruct->indexrelid;
+				idx_obj.objectSubId = 0;
+
+				recordDependencyOnOrError(rel, &idx_obj, object, error_out,
+										  DEPENDENCY_AUTO);
+			}
+		}
+		ReleaseSysCache(indexTuple);
+	}
+}
diff --git a/src/test/regress/expected/constraints.out b/src/test/regress/expected/constraints.out
index 1bbf59cca02..bcbf44b6f73 100644
--- a/src/test/regress/expected/constraints.out
+++ b/src/test/regress/expected/constraints.out
@@ -254,6 +254,27 @@ ERROR:  system column "ctid" reference in check constraint is invalid
 LINE 3:       CHECK (NOT (is_capital AND ctid::text = 'sys_col_check...
                                          ^
 --
+-- Drop column also drop all check constraints that have whole-row references.
+--
+-- Change column data type should error out because the whole-row referenced
+-- check constraint is still needed.
+-- no need to worry about partitioned tables, since the whole-row check constraint
+-- can not span multi relation.
+CREATE TABLE wholerow_check_tbl (
+    city int,
+    CONSTRAINT cc0 CHECK (wholerow_check_tbl is null) NOT ENFORCED,
+    CONSTRAINT cc1 CHECK (wholerow_check_tbl is not null) NOT ENFORCED);
+ALTER TABLE wholerow_check_tbl ALTER COLUMN city SET DATA TYPE INT8;
+ERROR:  cannot alter table "wholerow_check_tbl" because constraint cc0 on table wholerow_check_tbl uses its row type
+HINT:  You might need to drop constraint cc0 on table wholerow_check_tbl first
+ALTER TABLE wholerow_check_tbl DROP COLUMN city; --ok
+\d wholerow_check_tbl
+       Table "public.wholerow_check_tbl"
+ Column | Type | Collation | Nullable | Default 
+--------+------+-----------+----------+---------
+
+DROP TABLE wholerow_check_tbl;
+--
 -- Check inheritance of defaults and constraints
 --
 CREATE TABLE INSERT_CHILD (cx INT default 42,
diff --git a/src/test/regress/expected/indexing.out b/src/test/regress/expected/indexing.out
index 4d29fb85293..01f97812729 100644
--- a/src/test/regress/expected/indexing.out
+++ b/src/test/regress/expected/indexing.out
@@ -654,6 +654,41 @@ alter table idxpart2 drop column c;
  b      | integer |           |          | 
 
 drop table idxpart, idxpart2;
+--
+-- Drop column also drop all indexes that have whole-row references.
+--
+-- Change column data type should error out because the whole-row referenced
+-- indexex is still needed.
+create table idxpart (a int, b int, c int) partition by range (a);
+create table idxpart1 partition of idxpart for values from (2000) to (3000);
+create index idxpart_idx1 on idxpart1((idxpart1 is not null));
+alter table idxpart alter column b set data type int8; --error
+ERROR:  cannot alter table "idxpart1" because index idxpart_idx1 uses its row type
+HINT:  You might need to drop index idxpart_idx1 first
+drop index idxpart_idx1;
+create index idxpart_idx2 on idxpart1(a) where idxpart1 is not null;
+alter table idxpart alter column c set data type int8; --error
+ERROR:  cannot alter table "idxpart1" because index idxpart_idx2 uses its row type
+HINT:  You might need to drop index idxpart_idx2 first
+alter table idxpart drop column c;
+\d idxpart
+        Partitioned table "public.idxpart"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ a      | integer |           |          | 
+ b      | integer |           |          | 
+Partition key: RANGE (a)
+Number of partitions: 1 (Use \d+ to list them.)
+
+\d idxpart1
+              Table "public.idxpart1"
+ Column |  Type   | Collation | Nullable | Default 
+--------+---------+-----------+----------+---------
+ a      | integer |           |          | 
+ b      | integer |           |          | 
+Partition of: idxpart FOR VALUES FROM (2000) TO (3000)
+
+drop table idxpart;
 -- Verify that expression indexes inherit correctly
 create table idxpart (a int, b int) partition by range (a);
 create table idxpart1 (like idxpart);
diff --git a/src/test/regress/sql/constraints.sql b/src/test/regress/sql/constraints.sql
index 733a1dbccfe..a94aae7583b 100644
--- a/src/test/regress/sql/constraints.sql
+++ b/src/test/regress/sql/constraints.sql
@@ -165,6 +165,22 @@ CREATE TABLE SYS_COL_CHECK_TBL (city text, state text, is_capital bool,
                   altitude int,
 				  CHECK (NOT (is_capital AND ctid::text = 'sys_col_check_tbl')));
 
+--
+-- Drop column also drop all check constraints that have whole-row references.
+--
+-- Change column data type should error out because the whole-row referenced
+-- check constraint is still needed.
+-- no need to worry about partitioned tables, since the whole-row check constraint
+-- can not span multi relation.
+CREATE TABLE wholerow_check_tbl (
+    city int,
+    CONSTRAINT cc0 CHECK (wholerow_check_tbl is null) NOT ENFORCED,
+    CONSTRAINT cc1 CHECK (wholerow_check_tbl is not null) NOT ENFORCED);
+ALTER TABLE wholerow_check_tbl ALTER COLUMN city SET DATA TYPE INT8;
+ALTER TABLE wholerow_check_tbl DROP COLUMN city; --ok
+\d wholerow_check_tbl
+DROP TABLE wholerow_check_tbl;
+
 --
 -- Check inheritance of defaults and constraints
 --
diff --git a/src/test/regress/sql/indexing.sql b/src/test/regress/sql/indexing.sql
index b5cb01c2d70..0dfef988d0a 100644
--- a/src/test/regress/sql/indexing.sql
+++ b/src/test/regress/sql/indexing.sql
@@ -295,6 +295,26 @@ alter table idxpart2 drop column c;
 \d idxpart2
 drop table idxpart, idxpart2;
 
+--
+-- Drop column also drop all indexes that have whole-row references.
+--
+-- Change column data type should error out because the whole-row referenced
+-- indexex is still needed.
+create table idxpart (a int, b int, c int) partition by range (a);
+create table idxpart1 partition of idxpart for values from (2000) to (3000);
+
+create index idxpart_idx1 on idxpart1((idxpart1 is not null));
+alter table idxpart alter column b set data type int8; --error
+drop index idxpart_idx1;
+
+create index idxpart_idx2 on idxpart1(a) where idxpart1 is not null;
+alter table idxpart alter column c set data type int8; --error
+alter table idxpart drop column c;
+
+\d idxpart
+\d idxpart1
+drop table idxpart;
+
 -- Verify that expression indexes inherit correctly
 create table idxpart (a int, b int) partition by range (a);
 create table idxpart1 (like idxpart);
-- 
2.34.1

From 5e557d6c7c15bedc086576a5fdcfc7d47c9e2c8a Mon Sep 17 00:00:00 2001
From: jian he <[email protected]>
Date: Thu, 25 Dec 2025 22:59:19 +0800
Subject: [PATCH v7 3/3] disallow ALTER TABLE ALTER COLUMN when wholerow
 referenced policy exists

Policy have a DEPENDENCY_NORMAL type with their source table.  Policy's qual and
with check qual are quite unconstrained (allowing subqueries), we can't reliably
use pull_varattnos to detect if they contain subqueries.  A further complication
is that the qual and with check qual whole-row Var may not only references their
own table but also for other unrelated tables.

Therefore We should check pg_depend, not pg_policy, to see if dropping this
table affects any policy objects. After collecting the policies impacted by the
ALTER TABLE command, check each policy qual and with check qual, see if
whole-row references or not.

demo:
CREATE TABLE rls_tbl (a int, b int, c int);
CREATE TABLE t (a int);
CREATE POLICY p1 ON rls_tbl USING (rls_tbl >= ROW(1,1,1) and (select t is null from t));

ALTER TABLE t DROP COLUMN a; --error
ERROR:  cannot drop column a of table t because other objects depend on it
DETAIL:  policy p1 on table rls_tbl depends on column a of table t
HINT:  Use DROP ... CASCADE to drop the dependent objects too.

ALTER TABLE rls_tbl DROP COLUMN b; --error
ERROR:  cannot drop column b of table rls_tbl because other objects depend on it
DETAIL:  policy p1 on table rls_tbl depends on column b of table rls_tbl
HINT:  Use DROP ... CASCADE to drop the dependent objects too.

ALTER TABLE rls_tbl ALTER COLUMN b SET DATA TYPE BIGINT; --error
ERROR:  cannot alter table "rls_tbl" because security policy "p1" uses its row type
HINT:  You might need to drop policy "p1" first

ALTER TABLE t ALTER COLUMN a SET DATA TYPE BIGINT; --error
ERROR:  cannot alter table "t" because security policy "p1" uses its row type
HINT:  You might need to drop security policy "p1" first

discussion: https://postgr.es/m/CACJufxGA6KVQy7DbHGLVw9s9KKmpGyZt5ME6C7kEfjDpr2wZCw@mail.gmail.com
---
 src/backend/commands/tablecmds.c          | 123 ++++++++++++++++++++++
 src/backend/optimizer/util/var.c          |  59 +++++++++++
 src/include/optimizer/optimizer.h         |   1 +
 src/test/regress/expected/rowsecurity.out |  29 ++++-
 src/test/regress/sql/rowsecurity.sql      |  17 +++
 src/tools/pgindent/typedefs.list          |   1 +
 6 files changed, 228 insertions(+), 2 deletions(-)

diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 1e28f3af50b..95ed5e8876f 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -749,6 +749,8 @@ static void recordWholeRowDependencyOnOrError(Relation rel,
 											  const ObjectAddress *object,
 											  bool error_out);
 
+static List *GetRelPolicies(Relation rel);
+
 /* ----------------------------------------------------------------
  *		DefineRelation
  *				Creates a new relation.
@@ -23402,6 +23404,9 @@ recordWholeRowDependencyOnOrError(Relation rel, const ObjectAddress *object,
 	Datum		exprDatum;
 	char	   *exprString;
 	bool		isnull;
+	List	   *pols = NIL;
+	Relation	pg_policy;
+	Oid			reltypid;
 	bool		find_wholerow = false;
 	TupleConstr *constr = RelationGetDescr(rel)->constr;
 
@@ -23593,4 +23598,122 @@ recordWholeRowDependencyOnOrError(Relation rel, const ObjectAddress *object,
 			}
 		}
 	}
+
+	reltypid = get_rel_type_id(RelationGetRelid(rel));
+
+	pg_policy = table_open(PolicyRelationId, AccessShareLock);
+
+	pols = GetRelPolicies(rel);
+
+	foreach_oid(policyoid, pols)
+	{
+		ObjectAddress pol_obj;
+		SysScanDesc sscan;
+		HeapTuple	policy_tuple;
+		ScanKeyData polskey[1];
+
+		find_wholerow = false;
+
+		ScanKeyInit(&polskey[0],
+					Anum_pg_policy_oid,
+					BTEqualStrategyNumber, F_OIDEQ,
+					ObjectIdGetDatum(policyoid));
+		sscan = systable_beginscan(pg_policy,
+								   PolicyOidIndexId, true, NULL, 1,
+								   polskey);
+		while (HeapTupleIsValid(policy_tuple = systable_getnext(sscan)))
+		{
+			Form_pg_policy policy = (Form_pg_policy) GETSTRUCT(policy_tuple);
+
+			/* Get policy qual */
+			exprDatum = heap_getattr(policy_tuple, Anum_pg_policy_polqual,
+									 RelationGetDescr(pg_policy), &isnull);
+			if (!isnull)
+			{
+				exprString = TextDatumGetCString(exprDatum);
+				expr = (Node *) stringToNode(exprString);
+				pfree(exprString);
+
+				find_wholerow = ExprContainWholeRow(expr, reltypid);
+
+				if (find_wholerow)
+				{
+					pol_obj.classId = PolicyRelationId;
+					pol_obj.objectId = policy->oid;
+					pol_obj.objectSubId = 0;
+
+					recordDependencyOnOrError(rel, &pol_obj, object, error_out,
+											  DEPENDENCY_NORMAL);
+
+					continue;
+				}
+			}
+
+			exprDatum = heap_getattr(policy_tuple, Anum_pg_policy_polwithcheck,
+									 RelationGetDescr(pg_policy), &isnull);
+			if (!isnull)
+			{
+				exprString = TextDatumGetCString(exprDatum);
+				expr = (Node *) stringToNode(exprString);
+				pfree(exprString);
+
+				find_wholerow = ExprContainWholeRow(expr, reltypid);
+
+				if (find_wholerow)
+				{
+					pol_obj.classId = PolicyRelationId;
+					pol_obj.objectId = policy->oid;
+					pol_obj.objectSubId = 0;
+
+					recordDependencyOnOrError(rel, &pol_obj, object, error_out,
+											  DEPENDENCY_NORMAL);
+				}
+			}
+		}
+		systable_endscan(sscan);
+	}
+	table_close(pg_policy, AccessShareLock);
+}
+
+static List *
+GetRelPolicies(Relation rel)
+{
+	Relation	depRel;
+	ScanKeyData key[3];
+	SysScanDesc scan;
+	HeapTuple	depTup;
+	List	   *result = NIL;
+
+	depRel = table_open(DependRelationId, RowExclusiveLock);
+	ScanKeyInit(&key[0],
+				Anum_pg_depend_refclassid,
+				BTEqualStrategyNumber, F_OIDEQ,
+				ObjectIdGetDatum(RelationRelationId));
+	ScanKeyInit(&key[1],
+				Anum_pg_depend_refobjid,
+				BTEqualStrategyNumber, F_OIDEQ,
+				ObjectIdGetDatum(RelationGetRelid(rel)));
+	ScanKeyInit(&key[2],
+				Anum_pg_depend_refobjsubid,
+				BTEqualStrategyNumber, F_INT4EQ,
+				Int32GetDatum((int32) 0));
+
+	scan = systable_beginscan(depRel, DependReferenceIndexId, true,
+							  NULL, 3, key);
+	while (HeapTupleIsValid(depTup = systable_getnext(scan)))
+	{
+		Form_pg_depend foundDep = (Form_pg_depend) GETSTRUCT(depTup);
+		ObjectAddress foundObject;
+
+		foundObject.classId = foundDep->classid;
+		foundObject.objectId = foundDep->objid;
+		foundObject.objectSubId = foundDep->objsubid;
+
+		if (foundObject.classId == PolicyRelationId)
+			result = list_append_unique_oid(result, foundObject.objectId);
+	}
+	systable_endscan(scan);
+	table_close(depRel, NoLock);
+
+	return result;
 }
diff --git a/src/backend/optimizer/util/var.c b/src/backend/optimizer/util/var.c
index 8065237a189..244c866c170 100644
--- a/src/backend/optimizer/util/var.c
+++ b/src/backend/optimizer/util/var.c
@@ -49,6 +49,11 @@ typedef struct
 	int			sublevels_up;
 } pull_vars_context;
 
+typedef struct
+{
+	Oid			reltypid;	/* the whole-row typeid */
+} contain_wholerow_context;
+
 typedef struct
 {
 	int			var_location;
@@ -73,6 +78,7 @@ typedef struct
 static bool pull_varnos_walker(Node *node,
 							   pull_varnos_context *context);
 static bool pull_varattnos_walker(Node *node, pull_varattnos_context *context);
+static bool ExprContainWholeRow_walker(Node *node, contain_wholerow_context *context);
 static bool pull_vars_walker(Node *node, pull_vars_context *context);
 static bool contain_var_clause_walker(Node *node, void *context);
 static bool contain_vars_of_level_walker(Node *node, int *sublevels_up);
@@ -327,6 +333,59 @@ pull_varattnos_walker(Node *node, pull_varattnos_context *context)
 	return expression_tree_walker(node, pull_varattnos_walker, context);
 }
 
+static bool
+ExprContainWholeRow_walker(Node *node, contain_wholerow_context *context)
+{
+	if (node == NULL)
+		return false;
+
+	if (IsA(node, Var))
+	{
+		Var		   *var = (Var *) node;
+
+		if (var->varattno == InvalidAttrNumber &&
+			var->vartype == context->reltypid)
+			return true;
+
+		return false;
+	}
+
+	if (IsA(node, Query))
+	{
+		bool		result;
+
+		result = query_tree_walker((Query *) node, ExprContainWholeRow_walker,
+								   context, 0);
+		return result;
+	}
+
+	return expression_tree_walker(node, ExprContainWholeRow_walker, context);
+}
+
+/*
+ * ExprContainWholeRow -
+ *
+ * Determine whether an expression contains a whole-row Var, recursing as needed.
+ * For simple expressions without sublinks, pull_varattnos is usually sufficient
+ * to detect a whole-row Var. But if the node contains sublinks (unplanned
+ * subqueries), the check must instead rely on the whole-row type OID.
+ * Use ExprContainWholeRow to check whole-row var existsence when in doubt.
+ */
+bool
+ExprContainWholeRow(Node *node, Oid reltypid)
+{
+	contain_wholerow_context context;
+
+	context.reltypid = reltypid;
+
+	Assert(OidIsValid(reltypid));
+
+	return query_or_expression_tree_walker(node,
+										   ExprContainWholeRow_walker,
+										   &context,
+										   0);
+}
+
 
 /*
  * pull_vars_of_level
diff --git a/src/include/optimizer/optimizer.h b/src/include/optimizer/optimizer.h
index 44ec5296a18..34b8e7facb7 100644
--- a/src/include/optimizer/optimizer.h
+++ b/src/include/optimizer/optimizer.h
@@ -199,6 +199,7 @@ extern SortGroupClause *get_sortgroupref_clause_noerr(Index sortref,
 extern Bitmapset *pull_varnos(PlannerInfo *root, Node *node);
 extern Bitmapset *pull_varnos_of_level(PlannerInfo *root, Node *node, int levelsup);
 extern void pull_varattnos(Node *node, Index varno, Bitmapset **varattnos);
+extern bool ExprContainWholeRow(Node *node, Oid reltypid);
 extern List *pull_vars_of_level(Node *node, int levelsup);
 extern bool contain_var_clause(Node *node);
 extern bool contain_vars_of_level(Node *node, int levelsup);
diff --git a/src/test/regress/expected/rowsecurity.out b/src/test/regress/expected/rowsecurity.out
index c958ef4d70a..0bb74356fa7 100644
--- a/src/test/regress/expected/rowsecurity.out
+++ b/src/test/regress/expected/rowsecurity.out
@@ -2637,6 +2637,32 @@ SELECT * FROM document;
   14 |  11 |      1 | regress_rls_bob   | new novel                        | 
 (16 rows)
 
+--check drop column (no CASCADE) or alter column data type will fail because of
+--whole-row referenced security policy exists.
+DROP TABLE  part_document;
+ALTER TABLE document ADD COLUMN dummy INT4, ADD COLUMN dummy1 INT4;
+CREATE POLICY p7 ON document AS PERMISSIVE
+    USING (cid IS NOT NULL AND
+    (WITH cte AS (SELECT TRUE FROM uaccount
+        WHERE EXISTS (SELECT document FROM uaccount WHERE uaccount IS NULL))
+    SELECT * FROM cte));
+ALTER TABLE uaccount ALTER COLUMN seclv SET DATA TYPE BIGINT; --errror
+ERROR:  cannot alter table "uaccount" because policy p7 on table document uses its row type
+HINT:  You might need to drop policy p7 on table document first
+ALTER TABLE document ALTER COLUMN dummy SET DATA TYPE BIGINT; --error
+ERROR:  cannot alter table "document" because policy p7 on table document uses its row type
+HINT:  You might need to drop policy p7 on table document first
+ALTER TABLE document DROP COLUMN dummy; --error
+ERROR:  cannot drop column dummy of table document because other objects depend on it
+DETAIL:  policy p7 on table document depends on column dummy of table document
+HINT:  Use DROP ... CASCADE to drop the dependent objects too.
+ALTER TABLE uaccount DROP COLUMN seclv; --error
+ERROR:  cannot drop column seclv of table uaccount because other objects depend on it
+DETAIL:  policy p7 on table document depends on column seclv of table uaccount
+HINT:  Use DROP ... CASCADE to drop the dependent objects too.
+ALTER TABLE document DROP COLUMN dummy CASCADE; --ok
+NOTICE:  drop cascades to policy p7 on table document
+ALTER TABLE uaccount DROP COLUMN seclv CASCADE; --ok
 --
 -- ROLE/GROUP
 --
@@ -5105,12 +5131,11 @@ drop table rls_t, test_t;
 --
 RESET SESSION AUTHORIZATION;
 DROP SCHEMA regress_rls_schema CASCADE;
-NOTICE:  drop cascades to 30 other objects
+NOTICE:  drop cascades to 29 other objects
 DETAIL:  drop cascades to function f_leak(text)
 drop cascades to table uaccount
 drop cascades to table category
 drop cascades to table document
-drop cascades to table part_document
 drop cascades to table dependent
 drop cascades to table rec1
 drop cascades to table rec2
diff --git a/src/test/regress/sql/rowsecurity.sql b/src/test/regress/sql/rowsecurity.sql
index 5d923c5ca3b..76487b5e4ba 100644
--- a/src/test/regress/sql/rowsecurity.sql
+++ b/src/test/regress/sql/rowsecurity.sql
@@ -1163,6 +1163,23 @@ DROP POLICY p1 ON document;
 -- Just check everything went per plan
 SELECT * FROM document;
 
+--check drop column (no CASCADE) or alter column data type will fail because of
+--whole-row referenced security policy exists.
+DROP TABLE  part_document;
+ALTER TABLE document ADD COLUMN dummy INT4, ADD COLUMN dummy1 INT4;
+CREATE POLICY p7 ON document AS PERMISSIVE
+    USING (cid IS NOT NULL AND
+    (WITH cte AS (SELECT TRUE FROM uaccount
+        WHERE EXISTS (SELECT document FROM uaccount WHERE uaccount IS NULL))
+    SELECT * FROM cte));
+ALTER TABLE uaccount ALTER COLUMN seclv SET DATA TYPE BIGINT; --errror
+ALTER TABLE document ALTER COLUMN dummy SET DATA TYPE BIGINT; --error
+
+ALTER TABLE document DROP COLUMN dummy; --error
+ALTER TABLE uaccount DROP COLUMN seclv; --error
+ALTER TABLE document DROP COLUMN dummy CASCADE; --ok
+ALTER TABLE uaccount DROP COLUMN seclv CASCADE; --ok
+
 --
 -- ROLE/GROUP
 --
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index 5c88fa92f4e..a6118cc3f32 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -3575,6 +3575,7 @@ conn_oauth_scope_func
 conn_sasl_state_func
 contain_aggs_of_level_context
 contain_placeholder_references_context
+contain_wholerow_context
 convert_testexpr_context
 copy_data_dest_cb
 copy_data_source_cb
-- 
2.34.1

From 66061613623e4b1faa15d048d37fdfc3d9136904 Mon Sep 17 00:00:00 2001
From: jian he <[email protected]>
Date: Sat, 27 Dec 2025 10:55:24 +0800
Subject: [PATCH v7 2/3] disallow drop or change column if wholerow trigger
 exists

1. ALTER TABLE DROP COLUMN
ALTER TABLE DROP COLUMN will fail if any trigger WHEN clause have whole-row
reference.

In the recordWholeRowDependencyOnOrError function, we record a dependency
between the relation and the whole-row-referenced trigger.
later performMultipleDeletions will error out as expected.

2. ALTER COLUMN SET DATA TYPE
ALTER COLUMN SET DATA TYPE must error out if any trigger have whole-row reference

ALTER COLUMN SET DATA TYPE fundamentally changes the table's record type. At
present, records containing columns of different data types cannot be compared
(see record_eq). Therefore ALTER COLUMN SET DATA TYPE should errr out in this
case, otherwise any trigger WHEN clause that compares whole-row values may
always evaluate to erorr out.

discussion: https://postgr.es/m/CACJufxGA6KVQy7DbHGLVw9s9KKmpGyZt5ME6C7kEfjDpr2wZCw@mail.gmail.com
---
 src/backend/commands/tablecmds.c           | 35 ++++++++++++++++++++++
 src/test/regress/expected/foreign_data.out | 13 ++++++++
 src/test/regress/expected/triggers.out     | 27 +++++++++++++++++
 src/test/regress/sql/foreign_data.sql      |  9 ++++++
 src/test/regress/sql/triggers.sql          | 17 +++++++++++
 5 files changed, 101 insertions(+)

diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 714ab75e7b3..1e28f3af50b 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -23558,4 +23558,39 @@ recordWholeRowDependencyOnOrError(Relation rel, const ObjectAddress *object,
 		}
 		ReleaseSysCache(indexTuple);
 	}
+
+	if (rel->trigdesc != NULL)
+	{
+		ObjectAddress trig_obj;
+
+		TriggerDesc *trigdesc = rel->trigdesc;
+
+		for (int i = 0; i < trigdesc->numtriggers; i++)
+		{
+			Trigger    *trig = &trigdesc->triggers[i];
+
+			if (trig->tgqual != NULL)
+			{
+				expr_attrs = NULL;
+
+				expr = stringToNode(trig->tgqual);
+
+				pull_varattnos(expr, PRS2_OLD_VARNO, &expr_attrs);
+
+				pull_varattnos(expr, PRS2_NEW_VARNO, &expr_attrs);
+
+				find_wholerow = bms_is_member(0 - FirstLowInvalidHeapAttributeNumber,
+											  expr_attrs);
+				if (find_wholerow)
+				{
+					trig_obj.classId = TriggerRelationId;
+					trig_obj.objectId = trig->tgoid;
+					trig_obj.objectSubId = 0;
+
+					recordDependencyOnOrError(rel, &trig_obj, object, error_out,
+											  DEPENDENCY_NORMAL);
+				}
+			}
+		}
+	}
 }
diff --git a/src/test/regress/expected/foreign_data.out b/src/test/regress/expected/foreign_data.out
index cce49e509ab..c5b0ce10a60 100644
--- a/src/test/regress/expected/foreign_data.out
+++ b/src/test/regress/expected/foreign_data.out
@@ -1398,6 +1398,19 @@ DROP TRIGGER trigtest_before_stmt ON foreign_schema.foreign_table_1;
 DROP TRIGGER trigtest_before_row ON foreign_schema.foreign_table_1;
 DROP TRIGGER trigtest_after_stmt ON foreign_schema.foreign_table_1;
 DROP TRIGGER trigtest_after_row ON foreign_schema.foreign_table_1;
+CREATE TRIGGER trigtest_before_stmt BEFORE INSERT OR UPDATE
+ON foreign_schema.foreign_table_1
+FOR EACH ROW
+WHEN (new IS NOT NULL)
+EXECUTE PROCEDURE dummy_trigger();
+ALTER FOREIGN TABLE foreign_schema.foreign_table_1 ALTER COLUMN c7 SET DATA TYPE bigint; --error
+ERROR:  cannot alter table "foreign_table_1" because trigger trigtest_before_stmt on foreign table foreign_schema.foreign_table_1 uses its row type
+HINT:  You might need to drop trigger trigtest_before_stmt on foreign table foreign_schema.foreign_table_1 first
+ALTER FOREIGN TABLE foreign_schema.foreign_table_1 DROP COLUMN c7; --error
+ERROR:  cannot drop column c7 of foreign table foreign_schema.foreign_table_1 because other objects depend on it
+DETAIL:  trigger trigtest_before_stmt on foreign table foreign_schema.foreign_table_1 depends on column c7 of foreign table foreign_schema.foreign_table_1
+HINT:  Use DROP ... CASCADE to drop the dependent objects too.
+DROP TRIGGER trigtest_before_stmt ON foreign_schema.foreign_table_1;
 DROP FUNCTION dummy_trigger();
 -- Table inheritance
 CREATE TABLE fd_pt1 (
diff --git a/src/test/regress/expected/triggers.out b/src/test/regress/expected/triggers.out
index 1eb8fba0953..45389e8c94f 100644
--- a/src/test/regress/expected/triggers.out
+++ b/src/test/regress/expected/triggers.out
@@ -227,6 +227,33 @@ ERROR:  trigger "no_such_trigger" for table "main_table" does not exist
 COMMENT ON TRIGGER before_ins_stmt_trig ON main_table IS 'right';
 COMMENT ON TRIGGER before_ins_stmt_trig ON main_table IS NULL;
 --
+-- test triggers with WHEN clause contain wholerow reference
+--
+CREATE TABLE test_tbl1 (a int, b int) PARTITION BY RANGE (a);
+CREATE TABLE test_tbl1p1 PARTITION OF test_tbl1 FOR VALUES FROM (0) TO (1000);
+CREATE TRIGGER test_tbl1p1_trig
+    BEFORE INSERT OR UPDATE ON test_tbl1p1 FOR EACH ROW
+    WHEN (new = ROW (1, 1))
+    EXECUTE PROCEDURE trigger_func ('test_tbl1p1');
+ALTER TABLE test_tbl1 ALTER COLUMN b SET DATA TYPE bigint; --error
+ERROR:  cannot alter table "test_tbl1p1" because trigger test_tbl1p1_trig on table test_tbl1p1 uses its row type
+HINT:  You might need to drop trigger test_tbl1p1_trig on table test_tbl1p1 first
+ALTER TABLE test_tbl1 DROP COLUMN b; --error
+ERROR:  cannot drop desired object(s) because other objects depend on them
+DETAIL:  trigger test_tbl1p1_trig on table test_tbl1p1 depends on column b of table test_tbl1p1
+HINT:  Use DROP ... CASCADE to drop the dependent objects too.
+ALTER TABLE test_tbl1 DROP COLUMN b CASCADE; --ok
+NOTICE:  drop cascades to trigger test_tbl1p1_trig on table test_tbl1p1
+\d+ test_tbl1
+                           Partitioned table "public.test_tbl1"
+ Column |  Type   | Collation | Nullable | Default | Storage | Stats target | Description 
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ a      | integer |           |          |         | plain   |              | 
+Partition key: RANGE (a)
+Partitions: test_tbl1p1 FOR VALUES FROM (0) TO (1000)
+
+DROP TABLE test_tbl1;
+--
 -- test triggers with WHEN clause
 --
 CREATE TRIGGER modified_a BEFORE UPDATE OF a ON main_table
diff --git a/src/test/regress/sql/foreign_data.sql b/src/test/regress/sql/foreign_data.sql
index aa147b14a90..d36ec955861 100644
--- a/src/test/regress/sql/foreign_data.sql
+++ b/src/test/regress/sql/foreign_data.sql
@@ -630,6 +630,15 @@ DROP TRIGGER trigtest_before_row ON foreign_schema.foreign_table_1;
 DROP TRIGGER trigtest_after_stmt ON foreign_schema.foreign_table_1;
 DROP TRIGGER trigtest_after_row ON foreign_schema.foreign_table_1;
 
+CREATE TRIGGER trigtest_before_stmt BEFORE INSERT OR UPDATE
+ON foreign_schema.foreign_table_1
+FOR EACH ROW
+WHEN (new IS NOT NULL)
+EXECUTE PROCEDURE dummy_trigger();
+ALTER FOREIGN TABLE foreign_schema.foreign_table_1 ALTER COLUMN c7 SET DATA TYPE bigint; --error
+ALTER FOREIGN TABLE foreign_schema.foreign_table_1 DROP COLUMN c7; --error
+DROP TRIGGER trigtest_before_stmt ON foreign_schema.foreign_table_1;
+
 DROP FUNCTION dummy_trigger();
 
 -- Table inheritance
diff --git a/src/test/regress/sql/triggers.sql b/src/test/regress/sql/triggers.sql
index 5f7f75d7ba5..3236efec44f 100644
--- a/src/test/regress/sql/triggers.sql
+++ b/src/test/regress/sql/triggers.sql
@@ -158,6 +158,23 @@ COMMENT ON TRIGGER no_such_trigger ON main_table IS 'wrong';
 COMMENT ON TRIGGER before_ins_stmt_trig ON main_table IS 'right';
 COMMENT ON TRIGGER before_ins_stmt_trig ON main_table IS NULL;
 
+--
+-- test triggers with WHEN clause contain wholerow reference
+--
+CREATE TABLE test_tbl1 (a int, b int) PARTITION BY RANGE (a);
+CREATE TABLE test_tbl1p1 PARTITION OF test_tbl1 FOR VALUES FROM (0) TO (1000);
+
+CREATE TRIGGER test_tbl1p1_trig
+    BEFORE INSERT OR UPDATE ON test_tbl1p1 FOR EACH ROW
+    WHEN (new = ROW (1, 1))
+    EXECUTE PROCEDURE trigger_func ('test_tbl1p1');
+
+ALTER TABLE test_tbl1 ALTER COLUMN b SET DATA TYPE bigint; --error
+ALTER TABLE test_tbl1 DROP COLUMN b; --error
+ALTER TABLE test_tbl1 DROP COLUMN b CASCADE; --ok
+\d+ test_tbl1
+DROP TABLE test_tbl1;
+
 --
 -- test triggers with WHEN clause
 --
-- 
2.34.1

Reply via email to