From ce767406a0c4a2404822cfc43bd62fb7ba2514b2 Mon Sep 17 00:00:00 2001
From: Osumi Takamichi <osumi.takamichi@fujitsu.com>
Date: Thu, 5 Nov 2020 12:54:08 +0000
Subject: [PATCH v16] Support CREATE OR REPLACE TRIGGER

This patch extends the grammar of CREATE TRIGGER to
accept OR REPLACE clause in order to replace an
existing regular trigger. The purpose of this patch
is to support migration from Oracle Database to Postgres
by giving compatible syntax for trigger replacement.
This allows user to replace a regular existing trigger
while it doesn't allow them to replace a constraint
existing trigger, which is unique to Postgres.

Author: Takamichi Osumi <osumi.takamichi@fujitsu.com>
Reviewed-by: Peter Smith <smithpb2250@gmail.com>
Reviewed-by: Tom Lane <tgl@sss.pgh.pa.us>
Reviewed-by: Tsunakawa, Takayuki <tsunakawa.takay@fujitsu.com>
Discussion: https://www.postgresql.org/message-id/0DDF369B45A1B44B8A687ED43F06557C010BC362%40G01JPEXMBYT03
---
 doc/src/sgml/ref/create_trigger.sgml   |  21 +++-
 src/backend/commands/tablecmds.c       |   9 +-
 src/backend/commands/trigger.c         | 161 ++++++++++++++++++--------
 src/backend/nodes/copyfuncs.c          |   3 +-
 src/backend/nodes/equalfuncs.c         |   3 +-
 src/backend/parser/gram.y              |  24 ++--
 src/include/nodes/parsenodes.h         |   3 +-
 src/test/regress/expected/triggers.out | 202 +++++++++++++++++++++++++++++++++
 src/test/regress/sql/triggers.sql      | 195 +++++++++++++++++++++++++++++++
 9 files changed, 555 insertions(+), 66 deletions(-)

diff --git a/doc/src/sgml/ref/create_trigger.sgml b/doc/src/sgml/ref/create_trigger.sgml
index 60346e1..399106a 100644
--- a/doc/src/sgml/ref/create_trigger.sgml
+++ b/doc/src/sgml/ref/create_trigger.sgml
@@ -26,7 +26,7 @@ PostgreSQL documentation
 
  <refsynopsisdiv>
 <synopsis>
-CREATE [ CONSTRAINT ] TRIGGER <replaceable class="parameter">name</replaceable> { BEFORE | AFTER | INSTEAD OF } { <replaceable class="parameter">event</replaceable> [ OR ... ] }
+CREATE [ OR REPLACE ] [ CONSTRAINT ] TRIGGER <replaceable class="parameter">name</replaceable> { BEFORE | AFTER | INSTEAD OF } { <replaceable class="parameter">event</replaceable> [ OR ... ] }
     ON <replaceable class="parameter">table_name</replaceable>
     [ FROM <replaceable class="parameter">referenced_table_name</replaceable> ]
     [ NOT DEFERRABLE | [ DEFERRABLE ] [ INITIALLY IMMEDIATE | INITIALLY DEFERRED ] ]
@@ -48,14 +48,22 @@ CREATE [ CONSTRAINT ] TRIGGER <replaceable class="parameter">name</replaceable>
   <title>Description</title>
 
   <para>
-   <command>CREATE TRIGGER</command> creates a new trigger.  The
-   trigger will be associated with the specified table, view, or foreign table
+   <command>CREATE TRIGGER</command> creates a new trigger.
+   <command>CREATE OR REPLACE TRIGGER</command> will either create a
+   new trigger, or replace an existing regular trigger. The trigger will be
+   associated with the specified table, view, or foreign table
    and will execute the specified
    function <replaceable class="parameter">function_name</replaceable> when
    certain operations are performed on that table.
   </para>
 
   <para>
+   To replace the current definition of an existing regular trigger, use
+   <command>CREATE OR REPLACE TRIGGER</command>, by specifying the same
+   trigger's name and the corresponding table's name where the trigger belongs.
+  </para>
+
+  <para>
    The trigger can be specified to fire before the
    operation is attempted on a row (before constraints are checked and
    the <command>INSERT</command>, <command>UPDATE</command>, or
@@ -446,6 +454,13 @@ UPDATE OF <replaceable>column_name1</replaceable> [, <replaceable>column_name2</
   </para>
 
   <para>
+   <command>CREATE OR REPLACE TRIGGER</command> works only for replacing a regular
+   (not constraint) trigger with another regular trigger.
+   That means it is impossible to replace a regular trigger with a constraint trigger
+   and to replace a constraint trigger with another constraint trigger.
+  </para>
+
+  <para>
    A column-specific trigger (one defined using the <literal>UPDATE OF
    <replaceable>column_name</replaceable></literal> syntax) will fire when any
    of its columns are listed as targets in the <command>UPDATE</command>
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index a29c14b..d883e58 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -10518,6 +10518,8 @@ CreateFKCheckTrigger(Oid myRelOid, Oid refRelOid, Constraint *fkconstraint,
 	 * and "RI_ConstraintTrigger_c_NNNN" for the check triggers.
 	 */
 	fk_trigger = makeNode(CreateTrigStmt);
+	fk_trigger->replace = false;
+	fk_trigger->isconstraint = true;
 	fk_trigger->trigname = "RI_ConstraintTrigger_c";
 	fk_trigger->relation = NULL;
 	fk_trigger->row = true;
@@ -10538,7 +10540,6 @@ CreateFKCheckTrigger(Oid myRelOid, Oid refRelOid, Constraint *fkconstraint,
 	fk_trigger->columns = NIL;
 	fk_trigger->transitionRels = NIL;
 	fk_trigger->whenClause = NULL;
-	fk_trigger->isconstraint = true;
 	fk_trigger->deferrable = fkconstraint->deferrable;
 	fk_trigger->initdeferred = fkconstraint->initdeferred;
 	fk_trigger->constrrel = NULL;
@@ -10567,6 +10568,8 @@ createForeignKeyActionTriggers(Relation rel, Oid refRelOid, Constraint *fkconstr
 	 * DELETE action on the referenced table.
 	 */
 	fk_trigger = makeNode(CreateTrigStmt);
+	fk_trigger->replace = false;
+	fk_trigger->isconstraint = true;
 	fk_trigger->trigname = "RI_ConstraintTrigger_a";
 	fk_trigger->relation = NULL;
 	fk_trigger->row = true;
@@ -10575,7 +10578,6 @@ createForeignKeyActionTriggers(Relation rel, Oid refRelOid, Constraint *fkconstr
 	fk_trigger->columns = NIL;
 	fk_trigger->transitionRels = NIL;
 	fk_trigger->whenClause = NULL;
-	fk_trigger->isconstraint = true;
 	fk_trigger->constrrel = NULL;
 	switch (fkconstraint->fk_del_action)
 	{
@@ -10623,6 +10625,8 @@ createForeignKeyActionTriggers(Relation rel, Oid refRelOid, Constraint *fkconstr
 	 * UPDATE action on the referenced table.
 	 */
 	fk_trigger = makeNode(CreateTrigStmt);
+	fk_trigger->replace = false;
+	fk_trigger->isconstraint = true;
 	fk_trigger->trigname = "RI_ConstraintTrigger_a";
 	fk_trigger->relation = NULL;
 	fk_trigger->row = true;
@@ -10631,7 +10635,6 @@ createForeignKeyActionTriggers(Relation rel, Oid refRelOid, Constraint *fkconstr
 	fk_trigger->columns = NIL;
 	fk_trigger->transitionRels = NIL;
 	fk_trigger->whenClause = NULL;
-	fk_trigger->isconstraint = true;
 	fk_trigger->constrrel = NULL;
 	switch (fkconstraint->fk_upd_action)
 	{
diff --git a/src/backend/commands/trigger.c b/src/backend/commands/trigger.c
index 092ac16..01cfb74 100644
--- a/src/backend/commands/trigger.c
+++ b/src/backend/commands/trigger.c
@@ -31,6 +31,7 @@
 #include "catalog/pg_proc.h"
 #include "catalog/pg_trigger.h"
 #include "catalog/pg_type.h"
+#include "catalog/pg_depend.h"
 #include "commands/dbcommands.h"
 #include "commands/defrem.h"
 #include "commands/trigger.h"
@@ -168,15 +169,14 @@ CreateTrigger(CreateTrigStmt *stmt, const char *queryString,
 	char	   *qual;
 	Datum		values[Natts_pg_trigger];
 	bool		nulls[Natts_pg_trigger];
+	bool		replaces[Natts_pg_trigger];
 	Relation	rel;
 	AclResult	aclresult;
 	Relation	tgrel;
-	SysScanDesc tgscan;
-	ScanKeyData key;
 	Relation	pgrel;
 	HeapTuple	tuple;
 	Oid			funcrettype;
-	Oid			trigoid;
+	Oid			trigoid = InvalidOid;
 	char		internaltrigname[NAMEDATALEN];
 	char	   *trigname;
 	Oid			constrrelid = InvalidOid;
@@ -185,6 +185,10 @@ CreateTrigger(CreateTrigStmt *stmt, const char *queryString,
 	char	   *oldtablename = NULL;
 	char	   *newtablename = NULL;
 	bool		partition_recurse;
+	bool		was_replaced = false;
+	Oid			existing_constraint_oid = InvalidOid;
+	bool		trigger_exists = false;
+	bool		existing_isInternal = false;
 
 	if (OidIsValid(relOid))
 		rel = table_open(relOid, ShareRowExclusiveLock);
@@ -669,6 +673,85 @@ CreateTrigger(CreateTrigStmt *stmt, const char *queryString,
 		whenRtable = NIL;
 	}
 
+	/* Check if there is a pre-existing trigger of the same name */
+	tgrel = table_open(TriggerRelationId, RowExclusiveLock);
+	if (!isInternal)
+	{
+		ScanKeyData skeys[2];
+		SysScanDesc my_desc;
+
+		ScanKeyInit(&skeys[0],
+					Anum_pg_trigger_tgrelid,
+					BTEqualStrategyNumber, F_OIDEQ,
+					ObjectIdGetDatum(RelationGetRelid(rel)));
+
+		ScanKeyInit(&skeys[1],
+					Anum_pg_trigger_tgname,
+					BTEqualStrategyNumber, F_NAMEEQ,
+					CStringGetDatum(stmt->trigname));
+
+		my_desc = systable_beginscan(tgrel, TriggerRelidNameIndexId, true,
+									 NULL, 2, skeys);
+
+		/* There should be at most one matching tuple */
+		if (HeapTupleIsValid(tuple = systable_getnext(my_desc)))
+		{
+			Form_pg_trigger pg_trigger = (Form_pg_trigger) GETSTRUCT(tuple);
+
+			tuple = heap_copytuple(tuple);
+			trigoid = pg_trigger->oid;
+			existing_constraint_oid = pg_trigger->tgconstraint;
+			existing_isInternal = pg_trigger->tgisinternal;
+			trigger_exists = true;
+		}
+		systable_endscan(my_desc);
+	}
+
+	/* Generate the trigger's oid because there was no same name trigger. */
+	if (!trigger_exists)
+		trigoid = GetNewOidWithIndex(tgrel, TriggerOidIndexId,
+									 Anum_pg_trigger_oid);
+	else
+	{
+		/*
+		 * without OR REPLACE clause, can't override the trigger with the same
+		 * name.
+		 */
+		if (!stmt->replace)
+			ereport(ERROR,
+					(errcode(ERRCODE_DUPLICATE_OBJECT),
+					 errmsg("trigger \"%s\" for relation \"%s\" already exists",
+							stmt->trigname, RelationGetRelationName(rel))));
+
+		/*
+		 * An internal trigger cannot be replaced by another user defined
+		 * trigger. This should exclude the case that internal trigger is
+		 * child trigger of partition table and needs to be rewritten when the
+		 * parent trigger is replaced by user.
+		 */
+		if (existing_isInternal && !isInternal && !in_partition)
+			ereport(ERROR,
+					(errcode(ERRCODE_DUPLICATE_OBJECT),
+					 errmsg("trigger \"%s\" for relation \"%s\" is an internal trigger",
+							stmt->trigname, RelationGetRelationName(rel))));
+
+		/*
+		 * It is not allowed to replace with a constraint trigger. The OR
+		 * REPLACE syntax is not available for constraint triggers (see
+		 * gram.y).
+		 */
+		Assert(!stmt->isconstraint);
+
+		/*
+		 * It is not allowed to replace an existing constraint trigger.
+		 */
+		if (OidIsValid(existing_constraint_oid))
+			ereport(ERROR,
+					(errcode(ERRCODE_DUPLICATE_OBJECT),
+					 errmsg("trigger \"%s\" for relation \"%s\" is a constraint trigger",
+							stmt->trigname, RelationGetRelationName(rel))));
+	}
+
 	/*
 	 * Find and validate the trigger function.
 	 */
@@ -728,15 +811,6 @@ CreateTrigger(CreateTrigStmt *stmt, const char *queryString,
 	}
 
 	/*
-	 * Generate the trigger's OID now, so that we can use it in the name if
-	 * needed.
-	 */
-	tgrel = table_open(TriggerRelationId, RowExclusiveLock);
-
-	trigoid = GetNewOidWithIndex(tgrel, TriggerOidIndexId,
-								 Anum_pg_trigger_oid);
-
-	/*
 	 * If trigger is internally generated, modify the provided trigger name to
 	 * ensure uniqueness by appending the trigger OID.  (Callers will usually
 	 * supply a simple constant trigger name in these cases.)
@@ -754,37 +828,6 @@ CreateTrigger(CreateTrigStmt *stmt, const char *queryString,
 	}
 
 	/*
-	 * Scan pg_trigger for existing triggers on relation.  We do this only to
-	 * give a nice error message if there's already a trigger of the same
-	 * name.  (The unique index on tgrelid/tgname would complain anyway.) We
-	 * can skip this for internally generated triggers, since the name
-	 * modification above should be sufficient.
-	 *
-	 * NOTE that this is cool only because we have ShareRowExclusiveLock on
-	 * the relation, so the trigger set won't be changing underneath us.
-	 */
-	if (!isInternal)
-	{
-		ScanKeyInit(&key,
-					Anum_pg_trigger_tgrelid,
-					BTEqualStrategyNumber, F_OIDEQ,
-					ObjectIdGetDatum(RelationGetRelid(rel)));
-		tgscan = systable_beginscan(tgrel, TriggerRelidNameIndexId, true,
-									NULL, 1, &key);
-		while (HeapTupleIsValid(tuple = systable_getnext(tgscan)))
-		{
-			Form_pg_trigger pg_trigger = (Form_pg_trigger) GETSTRUCT(tuple);
-
-			if (namestrcmp(&(pg_trigger->tgname), trigname) == 0)
-				ereport(ERROR,
-						(errcode(ERRCODE_DUPLICATE_OBJECT),
-						 errmsg("trigger \"%s\" for relation \"%s\" already exists",
-								trigname, RelationGetRelationName(rel))));
-		}
-		systable_endscan(tgscan);
-	}
-
-	/*
 	 * Build the new pg_trigger tuple.
 	 *
 	 * When we're creating a trigger in a partition, we mark it as internal,
@@ -910,12 +953,29 @@ CreateTrigger(CreateTrigStmt *stmt, const char *queryString,
 	else
 		nulls[Anum_pg_trigger_tgnewtable - 1] = true;
 
-	tuple = heap_form_tuple(tgrel->rd_att, values, nulls);
-
 	/*
 	 * Insert tuple into pg_trigger.
 	 */
-	CatalogTupleInsert(tgrel, tuple);
+	if (!trigger_exists)
+	{
+		tuple = heap_form_tuple(tgrel->rd_att, values, nulls);
+		CatalogTupleInsert(tgrel, tuple);
+	}
+	else
+	{
+		TupleDesc	tupDesc;
+		HeapTuple	newtup;
+
+		tupDesc = RelationGetDescr(tgrel);
+		memset(replaces, true, sizeof(replaces));
+		replaces[Anum_pg_trigger_oid - 1] = false;
+		replaces[Anum_pg_trigger_tgrelid - 1] = false;
+		replaces[Anum_pg_trigger_tgname - 1] = false;
+		newtup = heap_modify_tuple(tuple, tupDesc, values, nulls, replaces);
+		CatalogTupleUpdate(tgrel, &tuple->t_self, newtup);
+		was_replaced = true;
+		heap_freetuple(newtup);
+	}
 
 	heap_freetuple(tuple);
 	table_close(tgrel, RowExclusiveLock);
@@ -960,6 +1020,15 @@ CreateTrigger(CreateTrigStmt *stmt, const char *queryString,
 	myself.objectId = trigoid;
 	myself.objectSubId = 0;
 
+	/*
+	 * In order to replace trigger, trigger should not be dependent on old
+	 * referenced objects. Remove the old dependencies and then register new
+	 * ones. In this case, while the old referenced object gets dropped,
+	 * trigger will remain in the database.
+	 */
+	if (was_replaced)
+		deleteDependencyRecordsFor(myself.classId, myself.objectId, true);
+
 	referenced.classId = ProcedureRelationId;
 	referenced.objectId = funcoid;
 	referenced.objectSubId = 0;
diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c
index 2b4d765..4b07617 100644
--- a/src/backend/nodes/copyfuncs.c
+++ b/src/backend/nodes/copyfuncs.c
@@ -4313,6 +4313,8 @@ _copyCreateTrigStmt(const CreateTrigStmt *from)
 	CreateTrigStmt *newnode = makeNode(CreateTrigStmt);
 
 	COPY_STRING_FIELD(trigname);
+	COPY_SCALAR_FIELD(replace);
+	COPY_SCALAR_FIELD(isconstraint);
 	COPY_NODE_FIELD(relation);
 	COPY_NODE_FIELD(funcname);
 	COPY_NODE_FIELD(args);
@@ -4321,7 +4323,6 @@ _copyCreateTrigStmt(const CreateTrigStmt *from)
 	COPY_SCALAR_FIELD(events);
 	COPY_NODE_FIELD(columns);
 	COPY_NODE_FIELD(whenClause);
-	COPY_SCALAR_FIELD(isconstraint);
 	COPY_NODE_FIELD(transitionRels);
 	COPY_SCALAR_FIELD(deferrable);
 	COPY_SCALAR_FIELD(initdeferred);
diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c
index e2d1b98..6e261db 100644
--- a/src/backend/nodes/equalfuncs.c
+++ b/src/backend/nodes/equalfuncs.c
@@ -2020,6 +2020,8 @@ static bool
 _equalCreateTrigStmt(const CreateTrigStmt *a, const CreateTrigStmt *b)
 {
 	COMPARE_STRING_FIELD(trigname);
+	COMPARE_SCALAR_FIELD(replace);
+	COMPARE_SCALAR_FIELD(isconstraint);
 	COMPARE_NODE_FIELD(relation);
 	COMPARE_NODE_FIELD(funcname);
 	COMPARE_NODE_FIELD(args);
@@ -2028,7 +2030,6 @@ _equalCreateTrigStmt(const CreateTrigStmt *a, const CreateTrigStmt *b)
 	COMPARE_SCALAR_FIELD(events);
 	COMPARE_NODE_FIELD(columns);
 	COMPARE_NODE_FIELD(whenClause);
-	COMPARE_SCALAR_FIELD(isconstraint);
 	COMPARE_NODE_FIELD(transitionRels);
 	COMPARE_SCALAR_FIELD(deferrable);
 	COMPARE_SCALAR_FIELD(initdeferred);
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 480d168..7dbaf67 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -5211,21 +5211,22 @@ am_type:
  *****************************************************************************/
 
 CreateTrigStmt:
-			CREATE TRIGGER name TriggerActionTime TriggerEvents ON
+			CREATE opt_or_replace TRIGGER name TriggerActionTime TriggerEvents ON
 			qualified_name TriggerReferencing TriggerForSpec TriggerWhen
 			EXECUTE FUNCTION_or_PROCEDURE func_name '(' TriggerFuncArgs ')'
 				{
 					CreateTrigStmt *n = makeNode(CreateTrigStmt);
-					n->trigname = $3;
-					n->relation = $7;
-					n->funcname = $13;
-					n->args = $15;
-					n->row = $9;
-					n->timing = $4;
-					n->events = intVal(linitial($5));
-					n->columns = (List *) lsecond($5);
-					n->whenClause = $10;
-					n->transitionRels = $8;
+					n->replace = $2;
+					n->trigname = $4;
+					n->relation = $8;
+					n->funcname = $14;
+					n->args = $16;
+					n->row = $10;
+					n->timing = $5;
+					n->events = intVal(linitial($6));
+					n->columns = (List *) lsecond($6);
+					n->whenClause = $11;
+					n->transitionRels = $9;
 					n->isconstraint  = false;
 					n->deferrable	 = false;
 					n->initdeferred  = false;
@@ -5238,6 +5239,7 @@ CreateTrigStmt:
 			EXECUTE FUNCTION_or_PROCEDURE func_name '(' TriggerFuncArgs ')'
 				{
 					CreateTrigStmt *n = makeNode(CreateTrigStmt);
+					n->replace = false;
 					n->trigname = $4;
 					n->relation = $8;
 					n->funcname = $17;
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index ff584f2..8361317 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2433,6 +2433,8 @@ typedef struct CreateAmStmt
 typedef struct CreateTrigStmt
 {
 	NodeTag		type;
+	bool		replace;		/* replace trigger if already exists */
+	bool		isconstraint;	/* This is a constraint trigger */
 	char	   *trigname;		/* TRIGGER's name */
 	RangeVar   *relation;		/* relation trigger is on */
 	List	   *funcname;		/* qual. name of function to call */
@@ -2444,7 +2446,6 @@ typedef struct CreateTrigStmt
 	int16		events;			/* "OR" of INSERT/UPDATE/DELETE/TRUNCATE */
 	List	   *columns;		/* column names, or NIL for all columns */
 	Node	   *whenClause;		/* qual expression, or NULL if none */
-	bool		isconstraint;	/* This is a constraint trigger */
 	/* explicitly named transition data */
 	List	   *transitionRels; /* TriggerTransition nodes, or NIL if none */
 	/* The remaining fields are only used for constraint triggers */
diff --git a/src/test/regress/expected/triggers.out b/src/test/regress/expected/triggers.out
index c19aac9..dac7d27 100644
--- a/src/test/regress/expected/triggers.out
+++ b/src/test/regress/expected/triggers.out
@@ -3140,3 +3140,205 @@ create trigger aft_row after insert or update on trigger_parted
 create table trigger_parted_p1 partition of trigger_parted for values in (1)
   partition by list (a);
 create table trigger_parted_p1_1 partition of trigger_parted_p1 for values in (1);
+--
+-- Test case for CREATE OR REPLACE TRIGGER
+--
+create table my_table (id integer);
+create function funcA() returns trigger as $$
+begin
+  raise notice 'hello from funcA';
+  return null;
+end; $$ language plpgsql;
+create function funcB() returns trigger as $$
+begin
+  raise notice 'hello from funcB';
+  return null;
+end; $$ language plpgsql;
+-- consider combination tests from 2 grammatical points
+-- (1) the trigger is a regular trigger or constraint trigger
+-- (2) OR REPLACE clause is used or not
+-- regular trigger cannot be replaced by another one without OR REPLACE clause
+create trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcA();
+create trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcB(); -- should fail
+ERROR:  trigger "my_trig" for relation "my_table" already exists
+drop trigger my_trig on my_table;
+-- regular trigger can be replaced by another one with OR REPLACE clause
+create trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcA();
+insert into my_table values (1);
+NOTICE:  hello from funcA
+create or replace trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcB(); -- OK
+insert into my_table values (1);
+NOTICE:  hello from funcB
+drop trigger my_trig on my_table;
+-- regular trigger cannot be replaced by constraint trigger
+create trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcA();
+create constraint trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcB(); -- should fail
+ERROR:  trigger "my_trig" for relation "my_table" already exists
+drop trigger my_trig on my_table;
+-- create or replace constraint trigger is not correct grammatically
+create trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcA();
+create or replace constraint trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcB(); -- should fail
+ERROR:  syntax error at or near "constraint"
+LINE 1: create or replace constraint trigger my_trig
+                          ^
+drop trigger my_trig on my_table;
+-- regular trigger cannot be replaced by another one without OR REPLACE clause
+create or replace trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcA();
+create trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcB(); -- should fail
+ERROR:  trigger "my_trig" for relation "my_table" already exists
+drop trigger my_trig on my_table;
+-- regular trigger can be replaced by another one with OR REPLACE clause
+create or replace trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcA();
+insert into my_table values (1);
+NOTICE:  hello from funcA
+create or replace trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcB(); -- OK
+insert into my_table values (1);
+NOTICE:  hello from funcB
+drop trigger my_trig on my_table;
+-- regular trigger cannot be replaced by constraint trigger
+create or replace trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcA();
+create constraint trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcB(); -- should fail
+ERROR:  trigger "my_trig" for relation "my_table" already exists
+drop trigger my_trig on my_table;
+-- create or replace constraint trigger is not correct gramatically
+create or replace trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcA();
+create or replace constraint trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcB(); -- should fail
+ERROR:  syntax error at or near "constraint"
+LINE 1: create or replace constraint trigger my_trig
+                          ^
+drop trigger my_trig on my_table;
+-- constraint trigger cannot be replaced by regular trigger
+create constraint trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcA();
+create trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcB(); -- should fail
+ERROR:  trigger "my_trig" for relation "my_table" already exists
+drop trigger my_trig on my_table;
+-- constraint trigger cannot be replaced by regular trigger even with OR REPLACE clause
+create constraint trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcA();
+create or replace trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcB(); -- should fail
+ERROR:  trigger "my_trig" for relation "my_table" is a constraint trigger
+drop trigger my_trig on my_table;
+-- constraint trigger cannot be replaced by constraint trigger
+create constraint trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcA();
+create constraint trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcB(); -- should fail
+ERROR:  trigger "my_trig" for relation "my_table" already exists
+drop trigger my_trig on my_table;
+-- create or replace constraint trigger is not gramatically correct.
+create trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcA();
+create or replace constraint trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcB(); -- should fail
+ERROR:  syntax error at or near "constraint"
+LINE 1: create or replace constraint trigger my_trig
+                          ^
+drop trigger my_trig on my_table;
+-- cleanup
+drop table my_table;
+drop function funcA();
+drop function funcB();
+-- test CREATE OR REPLACE TRIGGER on partition table
+create table parted_trig (a int) partition by range (a);
+create table parted_trig_1 partition of parted_trig
+       for values from (0) to (1000) partition by range (a);
+create table parted_trig_1_1 partition of parted_trig_1 for values from (0) to (100);
+create table parted_trig_2 partition of parted_trig for values from (1000) to (2000);
+create table default_parted_trig partition of parted_trig default;
+create function funcA() returns trigger as $$
+begin
+  raise notice 'hello from funcA';
+  return null;
+end; $$ language plpgsql;
+create function funcB() returns trigger as $$
+begin
+  raise notice 'hello from funcB';
+  return null;
+end; $$ language plpgsql;
+-- test that trigger can be replaced by another one
+-- at the same level of partition table
+create or replace trigger my_trig
+  after insert on parted_trig
+  for each row execute procedure funcA();
+insert into parted_trig (a) values (50);
+NOTICE:  hello from funcA
+create or replace trigger my_trig
+  after insert on parted_trig
+  for each row execute procedure funcB();
+insert into parted_trig (a) values (50);
+NOTICE:  hello from funcB
+truncate parted_trig;
+drop trigger my_trig on parted_trig;
+-- test that child trigger cannot be replaced directly
+create or replace trigger my_trig
+  after insert on parted_trig
+  for each row execute procedure funcA();
+insert into parted_trig (a) values (50);
+NOTICE:  hello from funcA
+create or replace trigger my_trig
+  after insert on parted_trig_1
+  for each row execute procedure funcB(); -- should fail
+ERROR:  trigger "my_trig" for relation "parted_trig_1" is an internal trigger
+insert into parted_trig (a) values (50);
+NOTICE:  hello from funcA
+drop trigger my_trig on parted_trig;
+-- test that trigger is overwritten by another one
+-- defined by upper level
+create or replace trigger my_trig
+  after insert on parted_trig_1
+  for each row execute procedure funcA();
+insert into parted_trig (a) values (50);
+NOTICE:  hello from funcA
+create or replace trigger my_trig
+  after insert on parted_trig
+  for each row execute procedure funcB();
+insert into parted_trig (a) values (50);
+NOTICE:  hello from funcB
+drop trigger my_trig on parted_trig;
+-- cleanup
+drop table parted_trig;
+drop function funcA();
+drop function funcB();
diff --git a/src/test/regress/sql/triggers.sql b/src/test/regress/sql/triggers.sql
index bf2e73a..96a03b6 100644
--- a/src/test/regress/sql/triggers.sql
+++ b/src/test/regress/sql/triggers.sql
@@ -2348,3 +2348,198 @@ create trigger aft_row after insert or update on trigger_parted
 create table trigger_parted_p1 partition of trigger_parted for values in (1)
   partition by list (a);
 create table trigger_parted_p1_1 partition of trigger_parted_p1 for values in (1);
+
+--
+-- Test case for CREATE OR REPLACE TRIGGER
+--
+create table my_table (id integer);
+create function funcA() returns trigger as $$
+begin
+  raise notice 'hello from funcA';
+  return null;
+end; $$ language plpgsql;
+create function funcB() returns trigger as $$
+begin
+  raise notice 'hello from funcB';
+  return null;
+end; $$ language plpgsql;
+
+-- consider combination tests from 2 grammatical points
+-- (1) the trigger is a regular trigger or constraint trigger
+-- (2) OR REPLACE clause is used or not
+
+-- regular trigger cannot be replaced by another one without OR REPLACE clause
+create trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcA();
+create trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcB(); -- should fail
+drop trigger my_trig on my_table;
+
+-- regular trigger can be replaced by another one with OR REPLACE clause
+create trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcA();
+insert into my_table values (1);
+create or replace trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcB(); -- OK
+insert into my_table values (1);
+drop trigger my_trig on my_table;
+
+-- regular trigger cannot be replaced by constraint trigger
+create trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcA();
+create constraint trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcB(); -- should fail
+drop trigger my_trig on my_table;
+
+-- create or replace constraint trigger is not correct grammatically
+create trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcA();
+create or replace constraint trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcB(); -- should fail
+drop trigger my_trig on my_table;
+
+-- regular trigger cannot be replaced by another one without OR REPLACE clause
+create or replace trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcA();
+create trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcB(); -- should fail
+drop trigger my_trig on my_table;
+
+-- regular trigger can be replaced by another one with OR REPLACE clause
+create or replace trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcA();
+insert into my_table values (1);
+create or replace trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcB(); -- OK
+insert into my_table values (1);
+drop trigger my_trig on my_table;
+
+-- regular trigger cannot be replaced by constraint trigger
+create or replace trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcA();
+create constraint trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcB(); -- should fail
+drop trigger my_trig on my_table;
+
+-- create or replace constraint trigger is not correct gramatically
+create or replace trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcA();
+create or replace constraint trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcB(); -- should fail
+drop trigger my_trig on my_table;
+
+-- constraint trigger cannot be replaced by regular trigger
+create constraint trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcA();
+create trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcB(); -- should fail
+drop trigger my_trig on my_table;
+
+-- constraint trigger cannot be replaced by regular trigger even with OR REPLACE clause
+create constraint trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcA();
+create or replace trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcB(); -- should fail
+drop trigger my_trig on my_table;
+
+-- constraint trigger cannot be replaced by constraint trigger
+create constraint trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcA();
+create constraint trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcB(); -- should fail
+drop trigger my_trig on my_table;
+
+-- create or replace constraint trigger is not gramatically correct.
+create trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcA();
+create or replace constraint trigger my_trig
+  after insert on my_table
+  for each row execute procedure funcB(); -- should fail
+drop trigger my_trig on my_table;
+
+-- cleanup
+drop table my_table;
+drop function funcA();
+drop function funcB();
+
+-- test CREATE OR REPLACE TRIGGER on partition table
+create table parted_trig (a int) partition by range (a);
+create table parted_trig_1 partition of parted_trig
+       for values from (0) to (1000) partition by range (a);
+create table parted_trig_1_1 partition of parted_trig_1 for values from (0) to (100);
+create table parted_trig_2 partition of parted_trig for values from (1000) to (2000);
+create table default_parted_trig partition of parted_trig default;
+create function funcA() returns trigger as $$
+begin
+  raise notice 'hello from funcA';
+  return null;
+end; $$ language plpgsql;
+create function funcB() returns trigger as $$
+begin
+  raise notice 'hello from funcB';
+  return null;
+end; $$ language plpgsql;
+
+-- test that trigger can be replaced by another one
+-- at the same level of partition table
+create or replace trigger my_trig
+  after insert on parted_trig
+  for each row execute procedure funcA();
+insert into parted_trig (a) values (50);
+create or replace trigger my_trig
+  after insert on parted_trig
+  for each row execute procedure funcB();
+insert into parted_trig (a) values (50);
+truncate parted_trig;
+drop trigger my_trig on parted_trig;
+
+-- test that child trigger cannot be replaced directly
+create or replace trigger my_trig
+  after insert on parted_trig
+  for each row execute procedure funcA();
+insert into parted_trig (a) values (50);
+create or replace trigger my_trig
+  after insert on parted_trig_1
+  for each row execute procedure funcB(); -- should fail
+insert into parted_trig (a) values (50);
+drop trigger my_trig on parted_trig;
+
+-- test that trigger is overwritten by another one
+-- defined by upper level
+create or replace trigger my_trig
+  after insert on parted_trig_1
+  for each row execute procedure funcA();
+insert into parted_trig (a) values (50);
+create or replace trigger my_trig
+  after insert on parted_trig
+  for each row execute procedure funcB();
+insert into parted_trig (a) values (50);
+drop trigger my_trig on parted_trig;
+
+-- cleanup
+drop table parted_trig;
+drop function funcA();
+drop function funcB();
-- 
1.8.3.1

