From bee202aa39d37c2887a33c2c6940a1fc791e722f Mon Sep 17 00:00:00 2001 From: Marco Slot Date: Fri, 25 Jun 2021 16:28:57 +0200 Subject: [PATCH 1/4] Fix PG upgrade scripts for 9.4 --- .../distributed/sql/citus--9.4-1--9.4-2.sql | 3 + .../distributed/sql/citus--9.4-2--9.4-1.sql | 9 ++ .../udfs/citus_finish_pg_upgrade/9.4-2.sql | 105 ++++++++++++++++++ .../udfs/citus_prepare_pg_upgrade/9.4-2.sql | 44 ++++++++ src/test/regress/expected/multi_extension.out | 23 ++++ src/test/regress/sql/multi_extension.sql | 14 +++ 6 files changed, 198 insertions(+) create mode 100644 src/backend/distributed/sql/citus--9.4-1--9.4-2.sql create mode 100644 src/backend/distributed/sql/citus--9.4-2--9.4-1.sql create mode 100644 src/backend/distributed/sql/udfs/citus_finish_pg_upgrade/9.4-2.sql create mode 100644 src/backend/distributed/sql/udfs/citus_prepare_pg_upgrade/9.4-2.sql diff --git a/src/backend/distributed/sql/citus--9.4-1--9.4-2.sql b/src/backend/distributed/sql/citus--9.4-1--9.4-2.sql new file mode 100644 index 000000000..97155bf27 --- /dev/null +++ b/src/backend/distributed/sql/citus--9.4-1--9.4-2.sql @@ -0,0 +1,3 @@ +-- 9.4-1--9.4-2 was added later as a patch to fix a bug in our PG upgrade functions +#include "udfs/citus_prepare_pg_upgrade/9.4-2.sql" +#include "udfs/citus_finish_pg_upgrade/9.4-2.sql" diff --git a/src/backend/distributed/sql/citus--9.4-2--9.4-1.sql b/src/backend/distributed/sql/citus--9.4-2--9.4-1.sql new file mode 100644 index 000000000..6f7b4306c --- /dev/null +++ b/src/backend/distributed/sql/citus--9.4-2--9.4-1.sql @@ -0,0 +1,9 @@ +-- +-- 9.4-1--9.4-2 was added later as a patch to fix a bug in our PG upgrade functions +-- +-- This script brings users who installed the patch released back to the 9.4-1 +-- upgrade path. We do this via a semantical downgrade since there has already been +-- introduced new changes in the schema from 9.4-1 to 9.5-1. To make sure we include all +-- changes made during that version change we decide to use the existing upgrade path from +-- our later introduced 9.4-2 version. +-- diff --git a/src/backend/distributed/sql/udfs/citus_finish_pg_upgrade/9.4-2.sql b/src/backend/distributed/sql/udfs/citus_finish_pg_upgrade/9.4-2.sql new file mode 100644 index 000000000..d1c88e45a --- /dev/null +++ b/src/backend/distributed/sql/udfs/citus_finish_pg_upgrade/9.4-2.sql @@ -0,0 +1,105 @@ +CREATE OR REPLACE FUNCTION pg_catalog.citus_finish_pg_upgrade() + RETURNS void + LANGUAGE plpgsql + SET search_path = pg_catalog + AS $cppu$ +DECLARE + table_name regclass; + command text; + trigger_name text; +BEGIN + -- + -- restore citus catalog tables + -- + INSERT INTO pg_catalog.pg_dist_partition SELECT * FROM public.pg_dist_partition; + INSERT INTO pg_catalog.pg_dist_shard SELECT * FROM public.pg_dist_shard; + INSERT INTO pg_catalog.pg_dist_placement SELECT * FROM public.pg_dist_placement; + INSERT INTO pg_catalog.pg_dist_node_metadata SELECT * FROM public.pg_dist_node_metadata; + INSERT INTO pg_catalog.pg_dist_node SELECT * FROM public.pg_dist_node; + INSERT INTO pg_catalog.pg_dist_local_group SELECT * FROM public.pg_dist_local_group; + INSERT INTO pg_catalog.pg_dist_transaction SELECT * FROM public.pg_dist_transaction; + INSERT INTO pg_catalog.pg_dist_colocation SELECT * FROM public.pg_dist_colocation; + -- enterprise catalog tables + INSERT INTO pg_catalog.pg_dist_authinfo SELECT * FROM public.pg_dist_authinfo; + INSERT INTO pg_catalog.pg_dist_poolinfo SELECT * FROM public.pg_dist_poolinfo; + + ALTER TABLE pg_catalog.pg_dist_rebalance_strategy DISABLE TRIGGER pg_dist_rebalance_strategy_enterprise_check_trigger; + INSERT INTO pg_catalog.pg_dist_rebalance_strategy SELECT + name, + default_strategy, + shard_cost_function::regprocedure::regproc, + node_capacity_function::regprocedure::regproc, + shard_allowed_on_node_function::regprocedure::regproc, + default_threshold, + minimum_threshold + FROM public.pg_dist_rebalance_strategy; + ALTER TABLE pg_catalog.pg_dist_rebalance_strategy ENABLE TRIGGER pg_dist_rebalance_strategy_enterprise_check_trigger; + + -- + -- drop backup tables + -- + DROP TABLE public.pg_dist_authinfo; + DROP TABLE public.pg_dist_colocation; + DROP TABLE public.pg_dist_local_group; + DROP TABLE public.pg_dist_node; + DROP TABLE public.pg_dist_node_metadata; + DROP TABLE public.pg_dist_partition; + DROP TABLE public.pg_dist_placement; + DROP TABLE public.pg_dist_poolinfo; + DROP TABLE public.pg_dist_shard; + DROP TABLE public.pg_dist_transaction; + + -- + -- reset sequences + -- + PERFORM setval('pg_catalog.pg_dist_shardid_seq', (SELECT MAX(shardid)+1 AS max_shard_id FROM pg_dist_shard), false); + PERFORM setval('pg_catalog.pg_dist_placement_placementid_seq', (SELECT MAX(placementid)+1 AS max_placement_id FROM pg_dist_placement), false); + PERFORM setval('pg_catalog.pg_dist_groupid_seq', (SELECT MAX(groupid)+1 AS max_group_id FROM pg_dist_node), false); + PERFORM setval('pg_catalog.pg_dist_node_nodeid_seq', (SELECT MAX(nodeid)+1 AS max_node_id FROM pg_dist_node), false); + PERFORM setval('pg_catalog.pg_dist_colocationid_seq', (SELECT MAX(colocationid)+1 AS max_colocation_id FROM pg_dist_colocation), false); + + -- + -- register triggers + -- + FOR table_name IN SELECT logicalrelid FROM pg_catalog.pg_dist_partition + LOOP + trigger_name := 'truncate_trigger_' || table_name::oid; + command := 'create trigger ' || trigger_name || ' after truncate on ' || table_name || ' execute procedure pg_catalog.citus_truncate_trigger()'; + EXECUTE command; + command := 'update pg_trigger set tgisinternal = true where tgname = ' || quote_literal(trigger_name); + EXECUTE command; + END LOOP; + + -- + -- set dependencies + -- + INSERT INTO pg_depend + SELECT + 'pg_class'::regclass::oid as classid, + p.logicalrelid::regclass::oid as objid, + 0 as objsubid, + 'pg_extension'::regclass::oid as refclassid, + (select oid from pg_extension where extname = 'citus') as refobjid, + 0 as refobjsubid , + 'n' as deptype + FROM pg_catalog.pg_dist_partition p; + + -- restore pg_dist_object from the stable identifiers + TRUNCATE citus.pg_dist_object; + INSERT INTO citus.pg_dist_object (classid, objid, objsubid, distribution_argument_index, colocationid) + SELECT + address.classid, + address.objid, + address.objsubid, + naming.distribution_argument_index, + naming.colocationid + FROM + public.pg_dist_object naming, + pg_catalog.pg_get_object_address(naming.type, naming.object_names, naming.object_args) address; + + DROP TABLE public.pg_dist_object; +END; +$cppu$; + +COMMENT ON FUNCTION pg_catalog.citus_finish_pg_upgrade() + IS 'perform tasks to restore citus settings from a location that has been prepared before pg_upgrade'; diff --git a/src/backend/distributed/sql/udfs/citus_prepare_pg_upgrade/9.4-2.sql b/src/backend/distributed/sql/udfs/citus_prepare_pg_upgrade/9.4-2.sql new file mode 100644 index 000000000..104f3d1b5 --- /dev/null +++ b/src/backend/distributed/sql/udfs/citus_prepare_pg_upgrade/9.4-2.sql @@ -0,0 +1,44 @@ +CREATE OR REPLACE FUNCTION pg_catalog.citus_prepare_pg_upgrade() + RETURNS void + LANGUAGE plpgsql + SET search_path = pg_catalog + AS $cppu$ +BEGIN + -- + -- backup citus catalog tables + -- + CREATE TABLE public.pg_dist_partition AS SELECT * FROM pg_catalog.pg_dist_partition; + CREATE TABLE public.pg_dist_shard AS SELECT * FROM pg_catalog.pg_dist_shard; + CREATE TABLE public.pg_dist_placement AS SELECT * FROM pg_catalog.pg_dist_placement; + CREATE TABLE public.pg_dist_node_metadata AS SELECT * FROM pg_catalog.pg_dist_node_metadata; + CREATE TABLE public.pg_dist_node AS SELECT * FROM pg_catalog.pg_dist_node; + CREATE TABLE public.pg_dist_local_group AS SELECT * FROM pg_catalog.pg_dist_local_group; + CREATE TABLE public.pg_dist_transaction AS SELECT * FROM pg_catalog.pg_dist_transaction; + CREATE TABLE public.pg_dist_colocation AS SELECT * FROM pg_catalog.pg_dist_colocation; + -- enterprise catalog tables + CREATE TABLE public.pg_dist_authinfo AS SELECT * FROM pg_catalog.pg_dist_authinfo; + CREATE TABLE public.pg_dist_poolinfo AS SELECT * FROM pg_catalog.pg_dist_poolinfo; + CREATE TABLE public.pg_dist_rebalance_strategy AS SELECT + name, + default_strategy, + shard_cost_function::regprocedure::text, + node_capacity_function::regprocedure::text, + shard_allowed_on_node_function::regprocedure::text, + default_threshold, + minimum_threshold + FROM pg_catalog.pg_dist_rebalance_strategy; + + -- store upgrade stable identifiers on pg_dist_object catalog + CREATE TABLE public.pg_dist_object AS SELECT + address.type, + address.object_names, + address.object_args, + objects.distribution_argument_index, + objects.colocationid + FROM citus.pg_dist_object objects, + pg_catalog.pg_identify_object_as_address(objects.classid, objects.objid, objects.objsubid) address; +END; +$cppu$; + +COMMENT ON FUNCTION pg_catalog.citus_prepare_pg_upgrade() + IS 'perform tasks to copy citus settings to a location that could later be restored after pg_upgrade is done'; diff --git a/src/test/regress/expected/multi_extension.out b/src/test/regress/expected/multi_extension.out index bd01a72b1..4f6728705 100644 --- a/src/test/regress/expected/multi_extension.out +++ b/src/test/regress/expected/multi_extension.out @@ -388,6 +388,29 @@ SELECT * FROM print_extension_changes(); | function worker_save_query_explain_analyze(text,jsonb) SETOF record (2 rows) +-- Test upgrade paths for backported citus_pg_upgrade functions +ALTER EXTENSION citus UPDATE TO '9.4-2'; +ALTER EXTENSION citus UPDATE TO '9.4-1'; +-- Should be empty result, even though the downgrade doesn't undo the upgrade, the +-- function signature doesn't change, which is reflected here. +SELECT * FROM print_extension_changes(); + previous_object | current_object +--------------------------------------------------------------------- +(0 rows) + +ALTER EXTENSION citus UPDATE TO '9.4-2'; +SELECT * FROM print_extension_changes(); + previous_object | current_object +--------------------------------------------------------------------- +(0 rows) + +-- Snapshot of state at 9.4-1 +ALTER EXTENSION citus UPDATE TO '9.4-1'; +SELECT * FROM print_extension_changes(); + previous_object | current_object +--------------------------------------------------------------------- +(0 rows) + -- Test downgrade to 9.4-1 from 9.5-1 ALTER EXTENSION citus UPDATE TO '9.5-1'; BEGIN; diff --git a/src/test/regress/sql/multi_extension.sql b/src/test/regress/sql/multi_extension.sql index 7bf553e02..82c1c1456 100644 --- a/src/test/regress/sql/multi_extension.sql +++ b/src/test/regress/sql/multi_extension.sql @@ -168,6 +168,20 @@ SELECT * FROM print_extension_changes(); ALTER EXTENSION citus UPDATE TO '9.4-1'; SELECT * FROM print_extension_changes(); +-- Test upgrade paths for backported citus_pg_upgrade functions +ALTER EXTENSION citus UPDATE TO '9.4-2'; +ALTER EXTENSION citus UPDATE TO '9.4-1'; +-- Should be empty result, even though the downgrade doesn't undo the upgrade, the +-- function signature doesn't change, which is reflected here. +SELECT * FROM print_extension_changes(); + +ALTER EXTENSION citus UPDATE TO '9.4-2'; +SELECT * FROM print_extension_changes(); + +-- Snapshot of state at 9.4-1 +ALTER EXTENSION citus UPDATE TO '9.4-1'; +SELECT * FROM print_extension_changes(); + -- Test downgrade to 9.4-1 from 9.5-1 ALTER EXTENSION citus UPDATE TO '9.5-1'; From 3c0dfc12c05922c3e338350f73ce0fa41c4c4912 Mon Sep 17 00:00:00 2001 From: Marco Slot Date: Fri, 25 Jun 2021 15:57:04 +0200 Subject: [PATCH 2/4] Fix PG upgrade scripts for 9.5 --- .../distributed/sql/citus--9.5-1--9.5-2.sql | 3 + .../distributed/sql/citus--9.5-2--9.5-1.sql | 9 ++ .../udfs/citus_finish_pg_upgrade/9.5-2.sql | 106 ++++++++++++++++++ .../udfs/citus_prepare_pg_upgrade/9.5-2.sql | 59 ++++++++++ src/test/regress/expected/multi_extension.out | 23 ++++ src/test/regress/sql/multi_extension.sql | 14 +++ 6 files changed, 214 insertions(+) create mode 100644 src/backend/distributed/sql/citus--9.5-1--9.5-2.sql create mode 100644 src/backend/distributed/sql/citus--9.5-2--9.5-1.sql create mode 100644 src/backend/distributed/sql/udfs/citus_finish_pg_upgrade/9.5-2.sql create mode 100644 src/backend/distributed/sql/udfs/citus_prepare_pg_upgrade/9.5-2.sql diff --git a/src/backend/distributed/sql/citus--9.5-1--9.5-2.sql b/src/backend/distributed/sql/citus--9.5-1--9.5-2.sql new file mode 100644 index 000000000..8af22f8db --- /dev/null +++ b/src/backend/distributed/sql/citus--9.5-1--9.5-2.sql @@ -0,0 +1,3 @@ +-- 9.5-1--9.5-2 was added later as a patch to fix a bug in our PG upgrade functions +#include "udfs/citus_prepare_pg_upgrade/9.5-2.sql" +#include "udfs/citus_finish_pg_upgrade/9.5-2.sql" diff --git a/src/backend/distributed/sql/citus--9.5-2--9.5-1.sql b/src/backend/distributed/sql/citus--9.5-2--9.5-1.sql new file mode 100644 index 000000000..580d2b4d6 --- /dev/null +++ b/src/backend/distributed/sql/citus--9.5-2--9.5-1.sql @@ -0,0 +1,9 @@ +-- +-- 9.5-1--9.5-2 was added later as a patch to fix a bug in our PG upgrade functions +-- +-- This script brings users who installed the patch released back to the 9.5-1 +-- upgrade path. We do this via a semantical downgrade since there has already been +-- introduced new changes in the schema from 9.5-1 to 10.0-1. To make sure we include all +-- changes made during that version change we decide to use the existing upgrade path from +-- our later introduced 9.5-1 version. +-- diff --git a/src/backend/distributed/sql/udfs/citus_finish_pg_upgrade/9.5-2.sql b/src/backend/distributed/sql/udfs/citus_finish_pg_upgrade/9.5-2.sql new file mode 100644 index 000000000..cdbde146c --- /dev/null +++ b/src/backend/distributed/sql/udfs/citus_finish_pg_upgrade/9.5-2.sql @@ -0,0 +1,106 @@ +CREATE OR REPLACE FUNCTION pg_catalog.citus_finish_pg_upgrade() + RETURNS void + LANGUAGE plpgsql + SET search_path = pg_catalog + AS $cppu$ +DECLARE + table_name regclass; + command text; + trigger_name text; +BEGIN + -- + -- restore citus catalog tables + -- + INSERT INTO pg_catalog.pg_dist_partition SELECT * FROM public.pg_dist_partition; + INSERT INTO pg_catalog.pg_dist_shard SELECT * FROM public.pg_dist_shard; + INSERT INTO pg_catalog.pg_dist_placement SELECT * FROM public.pg_dist_placement; + INSERT INTO pg_catalog.pg_dist_node_metadata SELECT * FROM public.pg_dist_node_metadata; + INSERT INTO pg_catalog.pg_dist_node SELECT * FROM public.pg_dist_node; + INSERT INTO pg_catalog.pg_dist_local_group SELECT * FROM public.pg_dist_local_group; + INSERT INTO pg_catalog.pg_dist_transaction SELECT * FROM public.pg_dist_transaction; + INSERT INTO pg_catalog.pg_dist_colocation SELECT * FROM public.pg_dist_colocation; + -- enterprise catalog tables + INSERT INTO pg_catalog.pg_dist_authinfo SELECT * FROM public.pg_dist_authinfo; + INSERT INTO pg_catalog.pg_dist_poolinfo SELECT * FROM public.pg_dist_poolinfo; + + ALTER TABLE pg_catalog.pg_dist_rebalance_strategy DISABLE TRIGGER pg_dist_rebalance_strategy_enterprise_check_trigger; + INSERT INTO pg_catalog.pg_dist_rebalance_strategy SELECT + name, + default_strategy, + shard_cost_function::regprocedure::regproc, + node_capacity_function::regprocedure::regproc, + shard_allowed_on_node_function::regprocedure::regproc, + default_threshold, + minimum_threshold + FROM public.pg_dist_rebalance_strategy; + ALTER TABLE pg_catalog.pg_dist_rebalance_strategy ENABLE TRIGGER pg_dist_rebalance_strategy_enterprise_check_trigger; + + -- + -- drop backup tables + -- + DROP TABLE public.pg_dist_authinfo; + DROP TABLE public.pg_dist_colocation; + DROP TABLE public.pg_dist_local_group; + DROP TABLE public.pg_dist_node; + DROP TABLE public.pg_dist_node_metadata; + DROP TABLE public.pg_dist_partition; + DROP TABLE public.pg_dist_placement; + DROP TABLE public.pg_dist_poolinfo; + DROP TABLE public.pg_dist_shard; + DROP TABLE public.pg_dist_transaction; + DROP TABLE public.pg_dist_rebalance_strategy; + + -- + -- reset sequences + -- + PERFORM setval('pg_catalog.pg_dist_shardid_seq', (SELECT MAX(shardid)+1 AS max_shard_id FROM pg_dist_shard), false); + PERFORM setval('pg_catalog.pg_dist_placement_placementid_seq', (SELECT MAX(placementid)+1 AS max_placement_id FROM pg_dist_placement), false); + PERFORM setval('pg_catalog.pg_dist_groupid_seq', (SELECT MAX(groupid)+1 AS max_group_id FROM pg_dist_node), false); + PERFORM setval('pg_catalog.pg_dist_node_nodeid_seq', (SELECT MAX(nodeid)+1 AS max_node_id FROM pg_dist_node), false); + PERFORM setval('pg_catalog.pg_dist_colocationid_seq', (SELECT MAX(colocationid)+1 AS max_colocation_id FROM pg_dist_colocation), false); + + -- + -- register triggers + -- + FOR table_name IN SELECT logicalrelid FROM pg_catalog.pg_dist_partition + LOOP + trigger_name := 'truncate_trigger_' || table_name::oid; + command := 'create trigger ' || trigger_name || ' after truncate on ' || table_name || ' execute procedure pg_catalog.citus_truncate_trigger()'; + EXECUTE command; + command := 'update pg_trigger set tgisinternal = true where tgname = ' || quote_literal(trigger_name); + EXECUTE command; + END LOOP; + + -- + -- set dependencies + -- + INSERT INTO pg_depend + SELECT + 'pg_class'::regclass::oid as classid, + p.logicalrelid::regclass::oid as objid, + 0 as objsubid, + 'pg_extension'::regclass::oid as refclassid, + (select oid from pg_extension where extname = 'citus') as refobjid, + 0 as refobjsubid , + 'n' as deptype + FROM pg_catalog.pg_dist_partition p; + + -- restore pg_dist_object from the stable identifiers + TRUNCATE citus.pg_dist_object; + INSERT INTO citus.pg_dist_object (classid, objid, objsubid, distribution_argument_index, colocationid) + SELECT + address.classid, + address.objid, + address.objsubid, + naming.distribution_argument_index, + naming.colocationid + FROM + public.pg_dist_object naming, + pg_catalog.pg_get_object_address(naming.type, naming.object_names, naming.object_args) address; + + DROP TABLE public.pg_dist_object; +END; +$cppu$; + +COMMENT ON FUNCTION pg_catalog.citus_finish_pg_upgrade() + IS 'perform tasks to restore citus settings from a location that has been prepared before pg_upgrade'; diff --git a/src/backend/distributed/sql/udfs/citus_prepare_pg_upgrade/9.5-2.sql b/src/backend/distributed/sql/udfs/citus_prepare_pg_upgrade/9.5-2.sql new file mode 100644 index 000000000..89e3ad3c6 --- /dev/null +++ b/src/backend/distributed/sql/udfs/citus_prepare_pg_upgrade/9.5-2.sql @@ -0,0 +1,59 @@ +CREATE OR REPLACE FUNCTION pg_catalog.citus_prepare_pg_upgrade() + RETURNS void + LANGUAGE plpgsql + SET search_path = pg_catalog + AS $cppu$ +BEGIN + -- + -- Drop existing backup tables + -- + DROP TABLE IF EXISTS public.pg_dist_partition; + DROP TABLE IF EXISTS public.pg_dist_shard; + DROP TABLE IF EXISTS public.pg_dist_placement; + DROP TABLE IF EXISTS public.pg_dist_node_metadata; + DROP TABLE IF EXISTS public.pg_dist_node; + DROP TABLE IF EXISTS public.pg_dist_local_group; + DROP TABLE IF EXISTS public.pg_dist_transaction; + DROP TABLE IF EXISTS public.pg_dist_colocation; + DROP TABLE IF EXISTS public.pg_dist_authinfo; + DROP TABLE IF EXISTS public.pg_dist_poolinfo; + DROP TABLE IF EXISTS public.pg_dist_rebalance_strategy; + + -- + -- backup citus catalog tables + -- + CREATE TABLE public.pg_dist_partition AS SELECT * FROM pg_catalog.pg_dist_partition; + CREATE TABLE public.pg_dist_shard AS SELECT * FROM pg_catalog.pg_dist_shard; + CREATE TABLE public.pg_dist_placement AS SELECT * FROM pg_catalog.pg_dist_placement; + CREATE TABLE public.pg_dist_node_metadata AS SELECT * FROM pg_catalog.pg_dist_node_metadata; + CREATE TABLE public.pg_dist_node AS SELECT * FROM pg_catalog.pg_dist_node; + CREATE TABLE public.pg_dist_local_group AS SELECT * FROM pg_catalog.pg_dist_local_group; + CREATE TABLE public.pg_dist_transaction AS SELECT * FROM pg_catalog.pg_dist_transaction; + CREATE TABLE public.pg_dist_colocation AS SELECT * FROM pg_catalog.pg_dist_colocation; + -- enterprise catalog tables + CREATE TABLE public.pg_dist_authinfo AS SELECT * FROM pg_catalog.pg_dist_authinfo; + CREATE TABLE public.pg_dist_poolinfo AS SELECT * FROM pg_catalog.pg_dist_poolinfo; + CREATE TABLE public.pg_dist_rebalance_strategy AS SELECT + name, + default_strategy, + shard_cost_function::regprocedure::text, + node_capacity_function::regprocedure::text, + shard_allowed_on_node_function::regprocedure::text, + default_threshold, + minimum_threshold + FROM pg_catalog.pg_dist_rebalance_strategy; + + -- store upgrade stable identifiers on pg_dist_object catalog + CREATE TABLE public.pg_dist_object AS SELECT + address.type, + address.object_names, + address.object_args, + objects.distribution_argument_index, + objects.colocationid + FROM citus.pg_dist_object objects, + pg_catalog.pg_identify_object_as_address(objects.classid, objects.objid, objects.objsubid) address; +END; +$cppu$; + +COMMENT ON FUNCTION pg_catalog.citus_prepare_pg_upgrade() + IS 'perform tasks to copy citus settings to a location that could later be restored after pg_upgrade is done'; diff --git a/src/test/regress/expected/multi_extension.out b/src/test/regress/expected/multi_extension.out index 4f6728705..fb1cb0b3d 100644 --- a/src/test/regress/expected/multi_extension.out +++ b/src/test/regress/expected/multi_extension.out @@ -459,6 +459,29 @@ SELECT * FROM print_extension_changes(); | function worker_record_sequence_dependency(regclass,regclass,name) void (10 rows) +-- Test upgrade paths for backported citus_pg_upgrade functions +ALTER EXTENSION citus UPDATE TO '9.5-2'; +ALTER EXTENSION citus UPDATE TO '9.5-1'; +-- Should be empty result, even though the downgrade doesn't undo the upgrade, the +-- function signature doesn't change, which is reflected here. +SELECT * FROM print_extension_changes(); + previous_object | current_object +--------------------------------------------------------------------- +(0 rows) + +ALTER EXTENSION citus UPDATE TO '9.5-2'; +SELECT * FROM print_extension_changes(); + previous_object | current_object +--------------------------------------------------------------------- +(0 rows) + +-- Snapshot of state at 9.5-1 +ALTER EXTENSION citus UPDATE TO '9.5-1'; +SELECT * FROM print_extension_changes(); + previous_object | current_object +--------------------------------------------------------------------- +(0 rows) + -- Test downgrade to 9.5-1 from 10.0-1 ALTER EXTENSION citus UPDATE TO '10.0-1'; ALTER EXTENSION citus UPDATE TO '9.5-1'; diff --git a/src/test/regress/sql/multi_extension.sql b/src/test/regress/sql/multi_extension.sql index 82c1c1456..2ea76cb68 100644 --- a/src/test/regress/sql/multi_extension.sql +++ b/src/test/regress/sql/multi_extension.sql @@ -204,6 +204,20 @@ SELECT * FROM print_extension_changes(); ALTER EXTENSION citus UPDATE TO '9.5-1'; SELECT * FROM print_extension_changes(); +-- Test upgrade paths for backported citus_pg_upgrade functions +ALTER EXTENSION citus UPDATE TO '9.5-2'; +ALTER EXTENSION citus UPDATE TO '9.5-1'; +-- Should be empty result, even though the downgrade doesn't undo the upgrade, the +-- function signature doesn't change, which is reflected here. +SELECT * FROM print_extension_changes(); + +ALTER EXTENSION citus UPDATE TO '9.5-2'; +SELECT * FROM print_extension_changes(); + +-- Snapshot of state at 9.5-1 +ALTER EXTENSION citus UPDATE TO '9.5-1'; +SELECT * FROM print_extension_changes(); + -- Test downgrade to 9.5-1 from 10.0-1 ALTER EXTENSION citus UPDATE TO '10.0-1'; ALTER EXTENSION citus UPDATE TO '9.5-1'; From b14955c2bd2768167b7b5fd3cbbe5fa489f85f84 Mon Sep 17 00:00:00 2001 From: Marco Slot Date: Fri, 25 Jun 2021 15:46:17 +0200 Subject: [PATCH 3/4] Fix PG upgrade scripts for 10.0 --- .../distributed/sql/citus--10.0-3--10.0-4.sql | 9 ++ .../sql/downgrades/citus--10.0-4--10.0-3.sql | 9 ++ .../udfs/citus_finish_pg_upgrade/10.0-4.sql | 108 ++++++++++++++++++ src/test/regress/expected/multi_extension.out | 21 +++- src/test/regress/sql/multi_extension.sql | 15 ++- 5 files changed, 158 insertions(+), 4 deletions(-) create mode 100644 src/backend/distributed/sql/citus--10.0-3--10.0-4.sql create mode 100644 src/backend/distributed/sql/downgrades/citus--10.0-4--10.0-3.sql create mode 100644 src/backend/distributed/sql/udfs/citus_finish_pg_upgrade/10.0-4.sql diff --git a/src/backend/distributed/sql/citus--10.0-3--10.0-4.sql b/src/backend/distributed/sql/citus--10.0-3--10.0-4.sql new file mode 100644 index 000000000..41bacdfea --- /dev/null +++ b/src/backend/distributed/sql/citus--10.0-3--10.0-4.sql @@ -0,0 +1,9 @@ +-- +-- 10.0-3--10.0-4 was added later as a patch to fix a bug in our PG upgrade functions +-- +-- Users who took the 9.5-2--10.0-1 upgrade path already have the fix, but users +-- who took the 9.5-1--10.0-1 upgrade path do not. Hence, we repeat the CREATE OR +-- REPLACE from the 9.5-2 definition for citus_prepare_pg_upgrade. + +#include "udfs/citus_prepare_pg_upgrade/9.5-2.sql" +#include "udfs/citus_finish_pg_upgrade/10.0-4.sql" diff --git a/src/backend/distributed/sql/downgrades/citus--10.0-4--10.0-3.sql b/src/backend/distributed/sql/downgrades/citus--10.0-4--10.0-3.sql new file mode 100644 index 000000000..5b26d8b22 --- /dev/null +++ b/src/backend/distributed/sql/downgrades/citus--10.0-4--10.0-3.sql @@ -0,0 +1,9 @@ +-- +-- 10.0-3--10.0-4 was added later as a patch to fix a bug in our PG upgrade functions +-- +-- The upgrade fixes a bug in citus_(prepare|finish)_pg_upgrade. Given the old versions of +-- these functions contain a bug it is better to _not_ restore the old version and keep +-- the patched version of the function. +-- +-- This is inline with the downgrade scripts for earlier versions of this patch +-- diff --git a/src/backend/distributed/sql/udfs/citus_finish_pg_upgrade/10.0-4.sql b/src/backend/distributed/sql/udfs/citus_finish_pg_upgrade/10.0-4.sql new file mode 100644 index 000000000..79153e9ae --- /dev/null +++ b/src/backend/distributed/sql/udfs/citus_finish_pg_upgrade/10.0-4.sql @@ -0,0 +1,108 @@ +CREATE OR REPLACE FUNCTION pg_catalog.citus_finish_pg_upgrade() + RETURNS void + LANGUAGE plpgsql + SET search_path = pg_catalog + AS $cppu$ +DECLARE + table_name regclass; + command text; + trigger_name text; +BEGIN + -- + -- restore citus catalog tables + -- + INSERT INTO pg_catalog.pg_dist_partition SELECT * FROM public.pg_dist_partition; + INSERT INTO pg_catalog.pg_dist_shard SELECT * FROM public.pg_dist_shard; + INSERT INTO pg_catalog.pg_dist_placement SELECT * FROM public.pg_dist_placement; + INSERT INTO pg_catalog.pg_dist_node_metadata SELECT * FROM public.pg_dist_node_metadata; + INSERT INTO pg_catalog.pg_dist_node SELECT * FROM public.pg_dist_node; + INSERT INTO pg_catalog.pg_dist_local_group SELECT * FROM public.pg_dist_local_group; + INSERT INTO pg_catalog.pg_dist_transaction SELECT * FROM public.pg_dist_transaction; + INSERT INTO pg_catalog.pg_dist_colocation SELECT * FROM public.pg_dist_colocation; + -- enterprise catalog tables + INSERT INTO pg_catalog.pg_dist_authinfo SELECT * FROM public.pg_dist_authinfo; + INSERT INTO pg_catalog.pg_dist_poolinfo SELECT * FROM public.pg_dist_poolinfo; + + ALTER TABLE pg_catalog.pg_dist_rebalance_strategy DISABLE TRIGGER pg_dist_rebalance_strategy_enterprise_check_trigger; + INSERT INTO pg_catalog.pg_dist_rebalance_strategy SELECT + name, + default_strategy, + shard_cost_function::regprocedure::regproc, + node_capacity_function::regprocedure::regproc, + shard_allowed_on_node_function::regprocedure::regproc, + default_threshold, + minimum_threshold + FROM public.pg_dist_rebalance_strategy; + ALTER TABLE pg_catalog.pg_dist_rebalance_strategy ENABLE TRIGGER pg_dist_rebalance_strategy_enterprise_check_trigger; + + -- + -- drop backup tables + -- + DROP TABLE public.pg_dist_authinfo; + DROP TABLE public.pg_dist_colocation; + DROP TABLE public.pg_dist_local_group; + DROP TABLE public.pg_dist_node; + DROP TABLE public.pg_dist_node_metadata; + DROP TABLE public.pg_dist_partition; + DROP TABLE public.pg_dist_placement; + DROP TABLE public.pg_dist_poolinfo; + DROP TABLE public.pg_dist_shard; + DROP TABLE public.pg_dist_transaction; + DROP TABLE public.pg_dist_rebalance_strategy; + + -- + -- reset sequences + -- + PERFORM setval('pg_catalog.pg_dist_shardid_seq', (SELECT MAX(shardid)+1 AS max_shard_id FROM pg_dist_shard), false); + PERFORM setval('pg_catalog.pg_dist_placement_placementid_seq', (SELECT MAX(placementid)+1 AS max_placement_id FROM pg_dist_placement), false); + PERFORM setval('pg_catalog.pg_dist_groupid_seq', (SELECT MAX(groupid)+1 AS max_group_id FROM pg_dist_node), false); + PERFORM setval('pg_catalog.pg_dist_node_nodeid_seq', (SELECT MAX(nodeid)+1 AS max_node_id FROM pg_dist_node), false); + PERFORM setval('pg_catalog.pg_dist_colocationid_seq', (SELECT MAX(colocationid)+1 AS max_colocation_id FROM pg_dist_colocation), false); + + -- + -- register triggers + -- + FOR table_name IN SELECT logicalrelid FROM pg_catalog.pg_dist_partition + LOOP + trigger_name := 'truncate_trigger_' || table_name::oid; + command := 'create trigger ' || trigger_name || ' after truncate on ' || table_name || ' execute procedure pg_catalog.citus_truncate_trigger()'; + EXECUTE command; + command := 'update pg_trigger set tgisinternal = true where tgname = ' || quote_literal(trigger_name); + EXECUTE command; + END LOOP; + + -- + -- set dependencies + -- + INSERT INTO pg_depend + SELECT + 'pg_class'::regclass::oid as classid, + p.logicalrelid::regclass::oid as objid, + 0 as objsubid, + 'pg_extension'::regclass::oid as refclassid, + (select oid from pg_extension where extname = 'citus') as refobjid, + 0 as refobjsubid , + 'n' as deptype + FROM pg_catalog.pg_dist_partition p; + + -- restore pg_dist_object from the stable identifiers + TRUNCATE citus.pg_dist_object; + INSERT INTO citus.pg_dist_object (classid, objid, objsubid, distribution_argument_index, colocationid) + SELECT + address.classid, + address.objid, + address.objsubid, + naming.distribution_argument_index, + naming.colocationid + FROM + public.pg_dist_object naming, + pg_catalog.pg_get_object_address(naming.type, naming.object_names, naming.object_args) address; + + DROP TABLE public.pg_dist_object; + + PERFORM citus_internal.columnar_ensure_objects_exist(); +END; +$cppu$; + +COMMENT ON FUNCTION pg_catalog.citus_finish_pg_upgrade() + IS 'perform tasks to restore citus settings from a location that has been prepared before pg_upgrade'; diff --git a/src/test/regress/expected/multi_extension.out b/src/test/regress/expected/multi_extension.out index fb1cb0b3d..028a1c934 100644 --- a/src/test/regress/expected/multi_extension.out +++ b/src/test/regress/expected/multi_extension.out @@ -598,9 +598,26 @@ SELECT * FROM print_extension_changes(); | function citus_get_active_worker_nodes() SETOF record (1 row) --- Test downgrade to 10.0-3 from 10.1-1 -ALTER EXTENSION citus UPDATE TO '10.1-1'; +-- Test downgrade to 10.0-3 from 10.0-4 +ALTER EXTENSION citus UPDATE TO '10.0-4'; ALTER EXTENSION citus UPDATE TO '10.0-3'; +-- Should be empty result, even though the downgrade doesn't undo the upgrade, the +-- function signature doesn't change, which is reflected here. +SELECT * FROM print_extension_changes(); + previous_object | current_object +--------------------------------------------------------------------- +(0 rows) + +-- Snapshot of state at 10.0-4 +ALTER EXTENSION citus UPDATE TO '10.0-4'; +SELECT * FROM print_extension_changes(); + previous_object | current_object +--------------------------------------------------------------------- +(0 rows) + +-- Test downgrade to 10.0-4 from 10.1-1 +ALTER EXTENSION citus UPDATE TO '10.1-1'; +ALTER EXTENSION citus UPDATE TO '10.0-4'; -- Should be empty result since upgrade+downgrade should be a no-op SELECT * FROM print_extension_changes(); previous_object | current_object diff --git a/src/test/regress/sql/multi_extension.sql b/src/test/regress/sql/multi_extension.sql index 2ea76cb68..0c862c24c 100644 --- a/src/test/regress/sql/multi_extension.sql +++ b/src/test/regress/sql/multi_extension.sql @@ -248,9 +248,20 @@ SELECT * FROM print_extension_changes(); ALTER EXTENSION citus UPDATE TO '10.0-3'; SELECT * FROM print_extension_changes(); --- Test downgrade to 10.0-3 from 10.1-1 -ALTER EXTENSION citus UPDATE TO '10.1-1'; +-- Test downgrade to 10.0-3 from 10.0-4 +ALTER EXTENSION citus UPDATE TO '10.0-4'; ALTER EXTENSION citus UPDATE TO '10.0-3'; +-- Should be empty result, even though the downgrade doesn't undo the upgrade, the +-- function signature doesn't change, which is reflected here. +SELECT * FROM print_extension_changes(); + +-- Snapshot of state at 10.0-4 +ALTER EXTENSION citus UPDATE TO '10.0-4'; +SELECT * FROM print_extension_changes(); + +-- Test downgrade to 10.0-4 from 10.1-1 +ALTER EXTENSION citus UPDATE TO '10.1-1'; +ALTER EXTENSION citus UPDATE TO '10.0-4'; -- Should be empty result since upgrade+downgrade should be a no-op SELECT * FROM print_extension_changes(); From 214c674989431d858bd468c1e0f1c706edb63e5a Mon Sep 17 00:00:00 2001 From: Marco Slot Date: Fri, 25 Jun 2021 15:46:47 +0200 Subject: [PATCH 4/4] Fix PG upgrade scripts for 10.1 --- ...3--10.1-1.sql => citus--10.0-4--10.1-1.sql} | 0 .../udfs/citus_finish_pg_upgrade/10.1-1.sql | 18 +++++------------- .../udfs/citus_finish_pg_upgrade/latest.sql | 18 +++++------------- .../udfs/citus_prepare_pg_upgrade/10.1-1.sql | 10 ++++++++-- .../udfs/citus_prepare_pg_upgrade/latest.sql | 10 ++++++++-- 5 files changed, 26 insertions(+), 30 deletions(-) rename src/backend/distributed/sql/{citus--10.0-3--10.1-1.sql => citus--10.0-4--10.1-1.sql} (100%) diff --git a/src/backend/distributed/sql/citus--10.0-3--10.1-1.sql b/src/backend/distributed/sql/citus--10.0-4--10.1-1.sql similarity index 100% rename from src/backend/distributed/sql/citus--10.0-3--10.1-1.sql rename to src/backend/distributed/sql/citus--10.0-4--10.1-1.sql diff --git a/src/backend/distributed/sql/udfs/citus_finish_pg_upgrade/10.1-1.sql b/src/backend/distributed/sql/udfs/citus_finish_pg_upgrade/10.1-1.sql index fdc05f6df..5902b646f 100644 --- a/src/backend/distributed/sql/udfs/citus_finish_pg_upgrade/10.1-1.sql +++ b/src/backend/distributed/sql/udfs/citus_finish_pg_upgrade/10.1-1.sql @@ -85,17 +85,7 @@ BEGIN FROM pg_catalog.pg_dist_partition p; -- restore pg_dist_object from the stable identifiers - -- DELETE/INSERT to avoid primary key violations - WITH old_records AS ( - DELETE FROM - citus.pg_dist_object - RETURNING - type, - object_names, - object_args, - distribution_argument_index, - colocationid - ) + TRUNCATE citus.pg_dist_object; INSERT INTO citus.pg_dist_object (classid, objid, objsubid, distribution_argument_index, colocationid) SELECT address.classid, @@ -104,8 +94,10 @@ BEGIN naming.distribution_argument_index, naming.colocationid FROM - old_records naming, - pg_get_object_address(naming.type, naming.object_names, naming.object_args) address; + public.pg_dist_object naming, + pg_catalog.pg_get_object_address(naming.type, naming.object_names, naming.object_args) address; + + DROP TABLE public.pg_dist_object; END; $cppu$; diff --git a/src/backend/distributed/sql/udfs/citus_finish_pg_upgrade/latest.sql b/src/backend/distributed/sql/udfs/citus_finish_pg_upgrade/latest.sql index fdc05f6df..5902b646f 100644 --- a/src/backend/distributed/sql/udfs/citus_finish_pg_upgrade/latest.sql +++ b/src/backend/distributed/sql/udfs/citus_finish_pg_upgrade/latest.sql @@ -85,17 +85,7 @@ BEGIN FROM pg_catalog.pg_dist_partition p; -- restore pg_dist_object from the stable identifiers - -- DELETE/INSERT to avoid primary key violations - WITH old_records AS ( - DELETE FROM - citus.pg_dist_object - RETURNING - type, - object_names, - object_args, - distribution_argument_index, - colocationid - ) + TRUNCATE citus.pg_dist_object; INSERT INTO citus.pg_dist_object (classid, objid, objsubid, distribution_argument_index, colocationid) SELECT address.classid, @@ -104,8 +94,10 @@ BEGIN naming.distribution_argument_index, naming.colocationid FROM - old_records naming, - pg_get_object_address(naming.type, naming.object_names, naming.object_args) address; + public.pg_dist_object naming, + pg_catalog.pg_get_object_address(naming.type, naming.object_names, naming.object_args) address; + + DROP TABLE public.pg_dist_object; END; $cppu$; diff --git a/src/backend/distributed/sql/udfs/citus_prepare_pg_upgrade/10.1-1.sql b/src/backend/distributed/sql/udfs/citus_prepare_pg_upgrade/10.1-1.sql index 8b4ce1479..8643f3943 100644 --- a/src/backend/distributed/sql/udfs/citus_prepare_pg_upgrade/10.1-1.sql +++ b/src/backend/distributed/sql/udfs/citus_prepare_pg_upgrade/10.1-1.sql @@ -45,8 +45,14 @@ BEGIN FROM pg_catalog.pg_dist_rebalance_strategy; -- store upgrade stable identifiers on pg_dist_object catalog - UPDATE citus.pg_dist_object - SET (type, object_names, object_args) = (SELECT * FROM pg_identify_object_as_address(classid, objid, objsubid)); + CREATE TABLE public.pg_dist_object AS SELECT + address.type, + address.object_names, + address.object_args, + objects.distribution_argument_index, + objects.colocationid + FROM citus.pg_dist_object objects, + pg_catalog.pg_identify_object_as_address(objects.classid, objects.objid, objects.objsubid) address; END; $cppu$; diff --git a/src/backend/distributed/sql/udfs/citus_prepare_pg_upgrade/latest.sql b/src/backend/distributed/sql/udfs/citus_prepare_pg_upgrade/latest.sql index 8b4ce1479..8643f3943 100644 --- a/src/backend/distributed/sql/udfs/citus_prepare_pg_upgrade/latest.sql +++ b/src/backend/distributed/sql/udfs/citus_prepare_pg_upgrade/latest.sql @@ -45,8 +45,14 @@ BEGIN FROM pg_catalog.pg_dist_rebalance_strategy; -- store upgrade stable identifiers on pg_dist_object catalog - UPDATE citus.pg_dist_object - SET (type, object_names, object_args) = (SELECT * FROM pg_identify_object_as_address(classid, objid, objsubid)); + CREATE TABLE public.pg_dist_object AS SELECT + address.type, + address.object_names, + address.object_args, + objects.distribution_argument_index, + objects.colocationid + FROM citus.pg_dist_object objects, + pg_catalog.pg_identify_object_as_address(objects.classid, objects.objid, objects.objsubid) address; END; $cppu$;