From b1a8fbd4c7df5a8d8a150339db812ea56c992f7c Mon Sep 17 00:00:00 2001
From: Ian Barwick <ian@2ndquadrant.com>
Date: Thu, 27 Nov 2014 16:05:13 +0900
Subject: [PATCH 37/37] deparse: initial testing framework

Test with:

make -C src/test/regress deparsecheck
---
 src/test/regress/GNUmakefile                       |  15 ++
 src/test/regress/expected/alter_table.out          |   4 +-
 .../regress/expected/create_function_ddl_demo.out  |   4 +
 src/test/regress/expected/deparse_init.out         | 177 ++++++++++++++++++++
 src/test/regress/expected/sanity_check.out         |   5 +-
 src/test/regress/input/deparse_test.source         |  57 +++++++
 src/test/regress/output/deparse_test.source        |  53 ++++++
 src/test/regress/pg_regress.c                      |  10 +-
 src/test/regress/sql/alter_table.sql               |   4 +-
 src/test/regress/sql/create_function_ddl_demo.sql  |   4 +
 src/test/regress/sql/deparse_init.sql              | 181 +++++++++++++++++++++
 src/test/regress/sql/sanity_check.sql              |   5 +-
 12 files changed, 511 insertions(+), 8 deletions(-)
 create mode 100644 src/test/regress/expected/create_function_ddl_demo.out
 create mode 100644 src/test/regress/expected/deparse_init.out
 create mode 100644 src/test/regress/input/deparse_test.source
 create mode 100644 src/test/regress/output/deparse_test.source
 create mode 100644 src/test/regress/sql/create_function_ddl_demo.sql
 create mode 100644 src/test/regress/sql/deparse_init.sql

diff --git a/src/test/regress/GNUmakefile b/src/test/regress/GNUmakefile
index 9eafcd8..b4ed761 100644
--- a/src/test/regress/GNUmakefile
+++ b/src/test/regress/GNUmakefile
@@ -133,6 +133,10 @@ tablespace-setup:
 generate-files:
 	$(top_builddir)/src/test/regress/pg_regress --generate-files-only --inputdir=$(srcdir)/input
 
+ddl_deparse_schedule: serial_schedule
+	echo "test: deparse_init" > $@
+	grep -v tablespace $(srcdir)/serial_schedule >> $@
+	echo "test: deparse_test" >> $@
 
 ##
 ## Run tests
@@ -158,6 +162,17 @@ installcheck-tests: all tablespace-setup
 standbycheck: all
 	$(pg_regress_installcheck) $(REGRESS_OPTS) --schedule=$(srcdir)/standby_schedule --use-existing
 
+deparsecheck: REGRESS_OPTS += --keep-install
+deparsecheck: all generate-files ddl_deparse_schedule
+	$(pg_regress_check) $(REGRESS_OPTS) --schedule=ddl_deparse_schedule
+	grep ERROR results/deparse_dump.out > results/deparse_dump.errors
+	$(bindir)/pg_ctl -w start -D ./tmp_check/data -l /dev/null
+	$(bindir)/pg_dump -d regression_deparse -s -f results/deparse.dump
+	$(bindir)/pg_dump -d regression -s -f results/regression.dump
+	$(bindir)/pg_ctl -D ./tmp_check/data stop
+	diff -c results/deparse.dump results/regression.dump
+	diff -c results/deparse_dump.errors $(srcdir)/expected/deparse_dump.errors
+
 # old interfaces follow...
 
 runcheck: check
diff --git a/src/test/regress/expected/alter_table.out b/src/test/regress/expected/alter_table.out
index 6a31df7..ea843ae 100644
--- a/src/test/regress/expected/alter_table.out
+++ b/src/test/regress/expected/alter_table.out
@@ -1858,7 +1858,9 @@ where virtualtransaction = (
         from pg_locks
         where transactionid = txid_current()::integer)
 and locktype = 'relation'
-and relnamespace != (select oid from pg_namespace where nspname = 'pg_catalog')
+and relnamespace NOT IN (
+	select oid from pg_namespace
+	where nspname IN ('pg_catalog', 'pg_deparse'))
 and c.relname != 'my_locks'
 group by c.relname;
 create table alterlock (f1 int primary key, f2 text);
diff --git a/src/test/regress/expected/create_function_ddl_demo.out b/src/test/regress/expected/create_function_ddl_demo.out
new file mode 100644
index 0000000..ff8a1d9
--- /dev/null
+++ b/src/test/regress/expected/create_function_ddl_demo.out
@@ -0,0 +1,4 @@
+CREATE FUNCTION check_foreign_key ()
+	RETURNS trigger
+	AS '/space/sda1/ibarwick/2ndquadrant_bdr/src/test/regress/refint.so'
+	LANGUAGE C;
diff --git a/src/test/regress/expected/deparse_init.out b/src/test/regress/expected/deparse_init.out
new file mode 100644
index 0000000..10ec843
--- /dev/null
+++ b/src/test/regress/expected/deparse_init.out
@@ -0,0 +1,177 @@
+--
+-- DEPARSE_INIT
+--
+CREATE SCHEMA deparse;
+UPDATE pg_namespace SET nspname = 'pg_deparse' WHERE nspname = 'deparse';
+CREATE UNLOGGED TABLE pg_deparse.deparse_test_commands (
+  backend_id int,
+  backend_start timestamptz,
+  lsn pg_lsn,
+  ord integer,
+  command TEXT
+);
+CREATE OR REPLACE FUNCTION pg_deparse.deparse_test_ddl_command_end()
+  RETURNS event_trigger
+  SECURITY DEFINER
+  LANGUAGE plpgsql
+AS $fn$
+BEGIN
+	BEGIN
+		INSERT INTO pg_deparse.deparse_test_commands
+		            (backend_id, backend_start, command, ord, lsn)
+		SELECT id, pg_stat_get_backend_start(id),
+		     pg_event_trigger_expand_command(command), ordinality, lsn
+		FROM pg_event_trigger_get_creation_commands() WITH ORDINALITY,
+		pg_current_xlog_insert_location() lsn,
+		pg_stat_get_backend_idset() id
+		 WHERE pg_stat_get_backend_pid(id) = pg_backend_pid() AND
+		NOT command_tag = 'CREATE TABLE AS EXECUTE';
+	EXCEPTION WHEN OTHERS THEN 
+			RAISE WARNING 'state: % errm: %', sqlstate, sqlerrm;
+	END;
+END;
+$fn$;
+CREATE OR REPLACE FUNCTION pg_deparse.deparse_test_sql_drop()
+  RETURNS event_trigger
+  SECURITY DEFINER
+  LANGUAGE plpgsql
+AS $fn$
+DECLARE
+fmt	TEXT;
+obj RECORD;
+i	integer = 1;
+BEGIN
+
+	/* This function runs in the sql_drop event trigger.
+     *
+	 * When it runs, we know that all objects reported by the
+	 * pg_event_trigger_dropped_objects() function marked as "original" have
+	 * been mentioned in the DROP command, either directly by name or
+	 * indirectly by owner (DROP OWNED BY).  Since no objects that depend on
+	 * them can persist after that, we can replicate the effect of that by
+	 * executing an equivalent "DROP IF EXISTS object ... CASCADE".  CASCADE
+	 * lets the deletion work even in presence of objects that appear further
+	 * down in the return set of pg_event_trigger_dropped_objects, while IF
+	 * EXISTS let the deletion silently do nothing if the object was already
+	 * dropped because it was dependent on another object before it in the same
+	 * result set.
+     *
+     * (In general, it is impossible to reorder the result set in a way that
+     * would be completely free of dependency issues.)
+     */
+
+	FOR obj IN
+	SELECT object_type, address_names, address_args, object_identity
+	  FROM pg_event_trigger_dropped_objects()
+	 WHERE original
+	  LOOP
+
+		-- special case for default acls: ignore them.
+		IF obj.object_type = 'default acl' THEN
+			CONTINUE;
+		END IF;
+
+		/*
+		 * special cases for objects that are part of other objects: drop
+		 * each in a separate command.  Since we only deal with "original"
+		 * objects, these would not be reported in the complex case of
+		 * DROP OWNED.
+		 */
+		IF obj.object_type = 'table column' OR obj.object_type = 'foreign table column' THEN
+			fmt = format('ALTER TABLE %I.%I DROP COLUMN %I CASCADE',
+				obj.address_names[1],
+				obj.address_names[2],
+				obj.address_names[3]);
+			-- ignore these; they are output by ALTER TABLE itself
+			fmt := NULL;
+		ELSIF obj.object_type = 'composite type column' THEN
+			fmt = format('ALTER TYPE %I.%I DROP ATTRIBUTE %I CASCADE',
+				obj.address_names[1],
+				obj.address_names[2],
+				obj.address_names[3]);
+			-- ignore these; they are output by ALTER TYPE itself
+			fmt := NULL;
+		ELSIF obj.object_type = 'table constraint' THEN
+			fmt = format('ALTER TABLE %I.%I DROP CONSTRAINT %I CASCADE',
+				obj.address_names[1],
+				obj.address_names[2],
+				obj.address_names[3]);
+			-- ignore these; they are output by ALTER TABLE itself
+			fmt := NULL;
+		ELSIF obj.object_type = 'domain constraint' THEN
+			fmt = format('ALTER DOMAIN %s DROP CONSTRAINT %I CASCADE',
+				obj.address_names[1],
+				obj.address_args[1]);
+		ELSIF obj.object_type = 'default value' THEN
+			fmt = format('ALTER TABLE %I.%I ALTER COLUMN %I DROP DEFAULT',
+				obj.address_names[1],
+				obj.address_names[2],
+				obj.address_names[3]);
+		ELSIF obj.object_type = 'foreign-data wrapper' THEN
+			fmt = format('DROP FOREIGN DATA WRAPPER IF EXISTS %s CASCADE',
+				obj.object_identity);
+		ELSIF obj.object_type = 'user mapping' THEN
+			fmt = format('DROP USER MAPPING FOR %I SERVER %I',
+				obj.address_names[1], obj.address_args[1]);
+		ELSIF obj.object_type = 'operator of access method' THEN
+			fmt = format('ALTER OPERATOR FAMILY %I.%I USING %I DROP OPERATOR %s (%s, %s)',
+				obj.address_names[2], obj.address_names[3], obj.address_names[1], obj.address_names[4],
+				obj.address_args[1], obj.address_args[2]);
+			-- ignore these; they are output by ALTER OPERATOR FAMILY itself
+			fmt := NULL;
+		ELSIF obj.object_type = 'function of access method' THEN
+			fmt = format('ALTER OPERATOR FAMILY %I.%I USING %I DROP FUNCTION %s (%s, %s)',
+				obj.address_names[2], obj.address_names[3], obj.address_names[1], obj.address_names[4],
+				obj.address_args[1], obj.address_args[2]);
+			-- ignore these; they are output by ALTER OPERATOR FAMILY itself
+			fmt := NULL;
+		ELSE
+			-- all other cases
+			fmt := format('DROP %s IF EXISTS %s CASCADE',
+				obj.object_type, obj.object_identity);
+		END IF;
+
+		IF fmt IS NULL THEN
+			CONTINUE;
+		END IF;
+
+		fmt := fmt || ' /* DROP support */';
+
+		INSERT INTO pg_deparse.deparse_test_commands
+		            (backend_id, backend_start, lsn, ord, command)
+			 SELECT id, pg_stat_get_backend_start(id),
+			        pg_current_xlog_insert_location(), i, fmt
+			   FROM pg_stat_get_backend_idset() id
+			  WHERE pg_stat_get_backend_pid(id) = pg_backend_pid();
+		i := i + 1;
+	END LOOP;
+END;
+$fn$;
+CREATE OR REPLACE FUNCTION pg_deparse.output_commands() RETURNS SETOF text LANGUAGE PLPGSQL AS $$
+DECLARE
+        cmd text;
+        prev_id int = -1;
+        prev_start timestamptz = '-infinity';
+        sess_id int;
+        sess_start timestamptz;
+BEGIN
+   FOR cmd, sess_id, sess_start IN
+			   SELECT command, backend_id, backend_start
+                 FROM pg_deparse.deparse_test_commands
+			 ORDER BY lsn, ord
+   LOOP
+          IF (sess_id, sess_start) <> (prev_id, prev_start) THEN
+                prev_id := sess_id;
+                prev_start := sess_start;
+                RETURN NEXT '\c';
+          END IF;
+      RETURN NEXT cmd || ';' ;
+   END LOOP;
+END;
+$$;
+CREATE EVENT TRIGGER deparse_test_trg_sql_drop
+  ON sql_drop
+  EXECUTE PROCEDURE pg_deparse.deparse_test_sql_drop();
+CREATE EVENT TRIGGER deparse_test_trg_ddl_command_end
+  ON ddl_command_end
+  EXECUTE PROCEDURE pg_deparse.deparse_test_ddl_command_end();
diff --git a/src/test/regress/expected/sanity_check.out b/src/test/regress/expected/sanity_check.out
index c7be273..5239fec 100644
--- a/src/test/regress/expected/sanity_check.out
+++ b/src/test/regress/expected/sanity_check.out
@@ -3,13 +3,14 @@ VACUUM;
 -- sanity check, if we don't have indices the test will take years to
 -- complete.  But skip TOAST relations (since they will have varying
 -- names depending on the current OID counter) as well as temp tables
--- of other backends (to avoid timing-dependent behavior).
+-- of other backends (to avoid timing-dependent behavior).  Also exclude
+-- the schema used for the deparse test, as it might not be there at all.
 --
 -- temporarily disable fancy output, so catalog changes create less diff noise
 \a\t
 SELECT relname, relhasindex
    FROM pg_class c LEFT JOIN pg_namespace n ON n.oid = relnamespace
-   WHERE relkind = 'r' AND (nspname ~ '^pg_temp_') IS NOT TRUE
+   WHERE relkind = 'r' AND (nspname ~ '^pg_temp_' OR nspname ~ '^pg_deparse') IS NOT TRUE
    ORDER BY relname;
 a|f
 a_star|f
diff --git a/src/test/regress/input/deparse_test.source b/src/test/regress/input/deparse_test.source
new file mode 100644
index 0000000..e7ba0dd
--- /dev/null
+++ b/src/test/regress/input/deparse_test.source
@@ -0,0 +1,57 @@
+---
+--- DEPARSE_TEST
+---
+
+-- create roles used throughout the tests
+create role clstr_user;
+create role "current_user";
+create role foreign_data_user;
+create role "Public";
+create role regressgroup1;
+create role regressgroup2;
+create role regression_bob;
+create role regression_group;
+create role regression_user1;
+create role regression_user2;
+create role regression_user3;
+create role regression_user;
+create role regresslo;
+create role regress_rol_lock1;
+create role regress_test_indirect;
+create role regress_test_role;
+create role regress_test_role2;
+create role regress_test_role_super superuser;
+create role regressuser1;
+create role regressuser2;
+create role regressuser3;
+create role regressuser4;
+create role regressuser5;
+create role regtest_unpriv_user;
+create role regtest_addr_user;
+create role regtest_alter_user1;
+create role regtest_alter_user2;
+create role regtest_alter_user3;
+create role rls_regress_group1;
+create role rls_regress_group2;
+create role rls_regress_user0;
+create role rls_regress_user1;
+create role rls_regress_user2;
+create role rls_regress_exempt_user;
+create role schemauser2;
+create role seclabel_user1;
+create role seclabel_user2;
+create role selinto_user;
+create role testrol1;
+create role testrol2;
+create role testrolx;
+create role unprivileged_role;
+create role "user";
+create role view_user2;
+
+\pset format unaligned
+\pset tuples_only
+\o ./sql/deparse_dump.sql
+
+SELECT * FROM pg_deparse.output_commands();
+
+\! @abs_builddir@/../../bin/psql/psql --dbname=@deparse_test_db@ -e < ./sql/deparse_dump.sql > results/deparse_dump.out 2>&1
diff --git a/src/test/regress/output/deparse_test.source b/src/test/regress/output/deparse_test.source
new file mode 100644
index 0000000..f083e7c
--- /dev/null
+++ b/src/test/regress/output/deparse_test.source
@@ -0,0 +1,53 @@
+---
+--- DEPARSE_TEST
+---
+-- create roles used throughout the tests
+create role clstr_user;
+create role "current_user";
+create role foreign_data_user;
+create role "Public";
+create role regressgroup1;
+create role regressgroup2;
+create role regression_bob;
+create role regression_group;
+create role regression_user1;
+create role regression_user2;
+create role regression_user3;
+create role regression_user;
+create role regresslo;
+create role regress_rol_lock1;
+create role regress_test_indirect;
+create role regress_test_role;
+create role regress_test_role2;
+create role regress_test_role_super superuser;
+create role regressuser1;
+create role regressuser2;
+create role regressuser3;
+create role regressuser4;
+create role regressuser5;
+create role regtest_unpriv_user;
+create role regtest_addr_user;
+create role regtest_alter_user1;
+create role regtest_alter_user2;
+create role regtest_alter_user3;
+create role rls_regress_group1;
+create role rls_regress_group2;
+create role rls_regress_user0;
+create role rls_regress_user1;
+create role rls_regress_user2;
+create role rls_regress_exempt_user;
+create role schemauser2;
+create role seclabel_user1;
+create role seclabel_user2;
+create role selinto_user;
+create role testrol1;
+create role testrol2;
+create role testrolx;
+create role unprivileged_role;
+create role "user";
+create role view_user2;
+\pset format unaligned
+\pset tuples_only
+\o ./sql/deparse_dump.sql
+SELECT * FROM pg_deparse.output_commands();
+\! @abs_builddir@/../../bin/psql/psql --dbname=@deparse_test_db@ -e < ./sql/deparse_dump.sql > results/deparse_dump.out 2>&1
diff --git a/src/test/regress/pg_regress.c b/src/test/regress/pg_regress.c
index d81e772..97d2e5b 100644
--- a/src/test/regress/pg_regress.c
+++ b/src/test/regress/pg_regress.c
@@ -108,6 +108,7 @@ static _stringlist *extraroles = NULL;
 static _stringlist *extra_install = NULL;
 static char *config_auth_datadir = NULL;
 static bool generate_files_only = false;
+static bool keep_install = false;
 
 /* internal variables */
 static const char *progname;
@@ -2161,6 +2162,7 @@ help(void)
 	printf(_("                            (can be used multiple times to concatenate)\n"));
 	printf(_("  --temp-install=DIR        create a temporary installation in DIR\n"));
 	printf(_("  --use-existing            use an existing installation\n"));
+	printf(_("  --keep-install            don't destroy nor stop the installation\n"));
 	printf(_("\n"));
 	printf(_("Options for \"temp-install\" mode:\n"));
 	printf(_("  --extra-install=DIR       additional directory to install (e.g., contrib)\n"));
@@ -2212,6 +2214,7 @@ regression_main(int argc, char *argv[], init_function ifunc, test_function tfunc
 		{"config-auth", required_argument, NULL, 24},
 		{"dbname-deparse", required_argument, NULL, 25},
 		{"generate-files-only", no_argument, NULL, 26},
+		{"keep-install", no_argument, NULL, 27},
 		{NULL, 0, NULL, 0}
 	};
 
@@ -2343,6 +2346,9 @@ regression_main(int argc, char *argv[], init_function ifunc, test_function tfunc
 			case 26:
 				generate_files_only = true;
 				break;
+			case 27:
+				keep_install = true;
+				break;
 			default:
 				/* getopt_long already emitted a complaint */
 				fprintf(stderr, _("\nTry \"%s -h\" for more information.\n"),
@@ -2692,7 +2698,7 @@ regression_main(int argc, char *argv[], init_function ifunc, test_function tfunc
 	/*
 	 * Shut down temp installation's postmaster
 	 */
-	if (temp_install)
+	if (temp_install && !keep_install)
 	{
 		header(_("shutting down postmaster"));
 		stop_postmaster();
@@ -2703,7 +2709,7 @@ regression_main(int argc, char *argv[], init_function ifunc, test_function tfunc
 	 * conserve disk space.  (If there were errors, we leave the installation
 	 * in place for possible manual investigation.)
 	 */
-	if (temp_install && fail_count == 0 && fail_ignore_count == 0)
+	if (temp_install && fail_count == 0 && fail_ignore_count == 0 && !keep_install)
 	{
 		header(_("removing temporary installation"));
 		if (!rmtree(temp_install, true))
diff --git a/src/test/regress/sql/alter_table.sql b/src/test/regress/sql/alter_table.sql
index b5ee7b0..1342c29 100644
--- a/src/test/regress/sql/alter_table.sql
+++ b/src/test/regress/sql/alter_table.sql
@@ -1289,7 +1289,9 @@ where virtualtransaction = (
         from pg_locks
         where transactionid = txid_current()::integer)
 and locktype = 'relation'
-and relnamespace != (select oid from pg_namespace where nspname = 'pg_catalog')
+and relnamespace NOT IN (
+	select oid from pg_namespace
+	where nspname IN ('pg_catalog', 'pg_deparse'))
 and c.relname != 'my_locks'
 group by c.relname;
 
diff --git a/src/test/regress/sql/create_function_ddl_demo.sql b/src/test/regress/sql/create_function_ddl_demo.sql
new file mode 100644
index 0000000..ac29426
--- /dev/null
+++ b/src/test/regress/sql/create_function_ddl_demo.sql
@@ -0,0 +1,4 @@
+CREATE FUNCTION check_foreign_key ()
+	RETURNS trigger
+	AS '/space/sda1/ibarwick/2ndquadrant_bdr/src/test/regress/refint.so'
+	LANGUAGE C;
\ No newline at end of file
diff --git a/src/test/regress/sql/deparse_init.sql b/src/test/regress/sql/deparse_init.sql
new file mode 100644
index 0000000..e90dcc1
--- /dev/null
+++ b/src/test/regress/sql/deparse_init.sql
@@ -0,0 +1,181 @@
+--
+-- DEPARSE_INIT
+--
+CREATE SCHEMA deparse;
+UPDATE pg_namespace SET nspname = 'pg_deparse' WHERE nspname = 'deparse';
+CREATE UNLOGGED TABLE pg_deparse.deparse_test_commands (
+  backend_id int,
+  backend_start timestamptz,
+  lsn pg_lsn,
+  ord integer,
+  command TEXT
+);
+CREATE OR REPLACE FUNCTION pg_deparse.deparse_test_ddl_command_end()
+  RETURNS event_trigger
+  SECURITY DEFINER
+  LANGUAGE plpgsql
+AS $fn$
+BEGIN
+	BEGIN
+		INSERT INTO pg_deparse.deparse_test_commands
+		            (backend_id, backend_start, command, ord, lsn)
+		SELECT id, pg_stat_get_backend_start(id),
+		     pg_event_trigger_expand_command(command), ordinality, lsn
+		FROM pg_event_trigger_get_creation_commands() WITH ORDINALITY,
+		pg_current_xlog_insert_location() lsn,
+		pg_stat_get_backend_idset() id
+		 WHERE pg_stat_get_backend_pid(id) = pg_backend_pid() AND
+		NOT command_tag = 'CREATE TABLE AS EXECUTE';
+	EXCEPTION WHEN OTHERS THEN 
+			RAISE WARNING 'state: % errm: %', sqlstate, sqlerrm;
+	END;
+END;
+$fn$;
+
+CREATE OR REPLACE FUNCTION pg_deparse.deparse_test_sql_drop()
+  RETURNS event_trigger
+  SECURITY DEFINER
+  LANGUAGE plpgsql
+AS $fn$
+DECLARE
+fmt	TEXT;
+obj RECORD;
+i	integer = 1;
+BEGIN
+
+	/* This function runs in the sql_drop event trigger.
+     *
+	 * When it runs, we know that all objects reported by the
+	 * pg_event_trigger_dropped_objects() function marked as "original" have
+	 * been mentioned in the DROP command, either directly by name or
+	 * indirectly by owner (DROP OWNED BY).  Since no objects that depend on
+	 * them can persist after that, we can replicate the effect of that by
+	 * executing an equivalent "DROP IF EXISTS object ... CASCADE".  CASCADE
+	 * lets the deletion work even in presence of objects that appear further
+	 * down in the return set of pg_event_trigger_dropped_objects, while IF
+	 * EXISTS let the deletion silently do nothing if the object was already
+	 * dropped because it was dependent on another object before it in the same
+	 * result set.
+     *
+     * (In general, it is impossible to reorder the result set in a way that
+     * would be completely free of dependency issues.)
+     */
+
+	FOR obj IN
+	SELECT object_type, address_names, address_args, object_identity
+	  FROM pg_event_trigger_dropped_objects()
+	 WHERE original
+	  LOOP
+
+		-- special case for default acls: ignore them.
+		IF obj.object_type = 'default acl' THEN
+			CONTINUE;
+		END IF;
+
+		/*
+		 * special cases for objects that are part of other objects: drop
+		 * each in a separate command.  Since we only deal with "original"
+		 * objects, these would not be reported in the complex case of
+		 * DROP OWNED.
+		 */
+		IF obj.object_type = 'table column' OR obj.object_type = 'foreign table column' THEN
+			fmt = format('ALTER TABLE %I.%I DROP COLUMN %I CASCADE',
+				obj.address_names[1],
+				obj.address_names[2],
+				obj.address_names[3]);
+			-- ignore these; they are output by ALTER TABLE itself
+			fmt := NULL;
+		ELSIF obj.object_type = 'composite type column' THEN
+			fmt = format('ALTER TYPE %I.%I DROP ATTRIBUTE %I CASCADE',
+				obj.address_names[1],
+				obj.address_names[2],
+				obj.address_names[3]);
+			-- ignore these; they are output by ALTER TYPE itself
+			fmt := NULL;
+		ELSIF obj.object_type = 'table constraint' THEN
+			fmt = format('ALTER TABLE %I.%I DROP CONSTRAINT %I CASCADE',
+				obj.address_names[1],
+				obj.address_names[2],
+				obj.address_names[3]);
+			-- ignore these; they are output by ALTER TABLE itself
+			fmt := NULL;
+		ELSIF obj.object_type = 'domain constraint' THEN
+			fmt = format('ALTER DOMAIN %s DROP CONSTRAINT %I CASCADE',
+				obj.address_names[1],
+				obj.address_args[1]);
+		ELSIF obj.object_type = 'default value' THEN
+			fmt = format('ALTER TABLE %I.%I ALTER COLUMN %I DROP DEFAULT',
+				obj.address_names[1],
+				obj.address_names[2],
+				obj.address_names[3]);
+		ELSIF obj.object_type = 'foreign-data wrapper' THEN
+			fmt = format('DROP FOREIGN DATA WRAPPER IF EXISTS %s CASCADE',
+				obj.object_identity);
+		ELSIF obj.object_type = 'user mapping' THEN
+			fmt = format('DROP USER MAPPING FOR %I SERVER %I',
+				obj.address_names[1], obj.address_args[1]);
+		ELSIF obj.object_type = 'operator of access method' THEN
+			fmt = format('ALTER OPERATOR FAMILY %I.%I USING %I DROP OPERATOR %s (%s, %s)',
+				obj.address_names[2], obj.address_names[3], obj.address_names[1], obj.address_names[4],
+				obj.address_args[1], obj.address_args[2]);
+			-- ignore these; they are output by ALTER OPERATOR FAMILY itself
+			fmt := NULL;
+		ELSIF obj.object_type = 'function of access method' THEN
+			fmt = format('ALTER OPERATOR FAMILY %I.%I USING %I DROP FUNCTION %s (%s, %s)',
+				obj.address_names[2], obj.address_names[3], obj.address_names[1], obj.address_names[4],
+				obj.address_args[1], obj.address_args[2]);
+			-- ignore these; they are output by ALTER OPERATOR FAMILY itself
+			fmt := NULL;
+		ELSE
+			-- all other cases
+			fmt := format('DROP %s IF EXISTS %s CASCADE',
+				obj.object_type, obj.object_identity);
+		END IF;
+
+		IF fmt IS NULL THEN
+			CONTINUE;
+		END IF;
+
+		fmt := fmt || ' /* DROP support */';
+
+		INSERT INTO pg_deparse.deparse_test_commands
+		            (backend_id, backend_start, lsn, ord, command)
+			 SELECT id, pg_stat_get_backend_start(id),
+			        pg_current_xlog_insert_location(), i, fmt
+			   FROM pg_stat_get_backend_idset() id
+			  WHERE pg_stat_get_backend_pid(id) = pg_backend_pid();
+		i := i + 1;
+	END LOOP;
+END;
+$fn$;
+
+CREATE OR REPLACE FUNCTION pg_deparse.output_commands() RETURNS SETOF text LANGUAGE PLPGSQL AS $$
+DECLARE
+        cmd text;
+        prev_id int = -1;
+        prev_start timestamptz = '-infinity';
+        sess_id int;
+        sess_start timestamptz;
+BEGIN
+   FOR cmd, sess_id, sess_start IN
+			   SELECT command, backend_id, backend_start
+                 FROM pg_deparse.deparse_test_commands
+			 ORDER BY lsn, ord
+   LOOP
+          IF (sess_id, sess_start) <> (prev_id, prev_start) THEN
+                prev_id := sess_id;
+                prev_start := sess_start;
+                RETURN NEXT '\c';
+          END IF;
+      RETURN NEXT cmd || ';' ;
+   END LOOP;
+END;
+$$;
+
+CREATE EVENT TRIGGER deparse_test_trg_sql_drop
+  ON sql_drop
+  EXECUTE PROCEDURE pg_deparse.deparse_test_sql_drop();
+
+CREATE EVENT TRIGGER deparse_test_trg_ddl_command_end
+  ON ddl_command_end
+  EXECUTE PROCEDURE pg_deparse.deparse_test_ddl_command_end();
diff --git a/src/test/regress/sql/sanity_check.sql b/src/test/regress/sql/sanity_check.sql
index 0da838e..1d7a276 100644
--- a/src/test/regress/sql/sanity_check.sql
+++ b/src/test/regress/sql/sanity_check.sql
@@ -4,7 +4,8 @@ VACUUM;
 -- sanity check, if we don't have indices the test will take years to
 -- complete.  But skip TOAST relations (since they will have varying
 -- names depending on the current OID counter) as well as temp tables
--- of other backends (to avoid timing-dependent behavior).
+-- of other backends (to avoid timing-dependent behavior).  Also exclude
+-- the schema used for the deparse test, as it might not be there at all.
 --
 
 -- temporarily disable fancy output, so catalog changes create less diff noise
@@ -12,7 +13,7 @@ VACUUM;
 
 SELECT relname, relhasindex
    FROM pg_class c LEFT JOIN pg_namespace n ON n.oid = relnamespace
-   WHERE relkind = 'r' AND (nspname ~ '^pg_temp_') IS NOT TRUE
+   WHERE relkind = 'r' AND (nspname ~ '^pg_temp_' OR nspname ~ '^pg_deparse') IS NOT TRUE
    ORDER BY relname;
 
 -- restore normal output mode
-- 
2.1.4

