From 28b9758e77438f3573f70aa95126680292e8da5c Mon Sep 17 00:00:00 2001 From: Andrew Farries Date: Wed, 18 Oct 2023 13:22:47 +0100 Subject: [PATCH 1/6] Add `SECURITY DEFINER` to `raw_migration` func This function must be able to write to the `pgroll.migrations` table regardless of the permissions of the user who causes it to be executed. --- pkg/state/state.go | 3 ++- 1 file changed, 2 insertions(+), 1 deletion(-) diff --git a/pkg/state/state.go b/pkg/state/state.go index 457d5386..b9312bc7 100644 --- a/pkg/state/state.go +++ b/pkg/state/state.go @@ -153,7 +153,8 @@ END; $$; CREATE OR REPLACE FUNCTION %[1]s.raw_migration() RETURNS event_trigger -LANGUAGE plpgsql AS $$ +LANGUAGE plpgsql +SECURITY DEFINER AS $$ DECLARE schemaname TEXT; BEGIN From 390f48aa6beb2216cef85ba47dd11f64fc1b75a4 Mon Sep 17 00:00:00 2001 From: Andrew Farries Date: Wed, 18 Oct 2023 13:25:06 +0100 Subject: [PATCH 2/6] Add `SECURITY DEFINER` to `latest_version` func This function needs to be able to read the `pgroll.migrations` table regardless of the permissions of the invoking user. --- pkg/state/state.go | 1 + 1 file changed, 1 insertion(+) diff --git a/pkg/state/state.go b/pkg/state/state.go index b9312bc7..fb9a8440 100644 --- a/pkg/state/state.go +++ b/pkg/state/state.go @@ -51,6 +51,7 @@ CREATE OR REPLACE FUNCTION %[1]s.is_active_migration_period(schemaname NAME) RET -- Get the latest version name (this is the one with child migrations) CREATE OR REPLACE FUNCTION %[1]s.latest_version(schemaname NAME) RETURNS text +SECURITY DEFINER AS $$ SELECT p.name FROM %[1]s.migrations p WHERE NOT EXISTS ( From aed4d734d5eeba4069b319de9817f36854437b20 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Carlos=20P=C3=A9rez-Aradros=20Herce?= Date: Tue, 24 Oct 2023 11:29:43 +0200 Subject: [PATCH 3/6] Set search_path, namespace function calls --- pkg/state/state.go | 14 ++++++++------ 1 file changed, 8 insertions(+), 6 deletions(-) diff --git a/pkg/state/state.go b/pkg/state/state.go index fb9a8440..f2ffe4b4 100644 --- a/pkg/state/state.go +++ b/pkg/state/state.go @@ -52,6 +52,7 @@ CREATE OR REPLACE FUNCTION %[1]s.is_active_migration_period(schemaname NAME) RET -- Get the latest version name (this is the one with child migrations) CREATE OR REPLACE FUNCTION %[1]s.latest_version(schemaname NAME) RETURNS text SECURITY DEFINER +SET search_path = %[1]s, pg_catalog AS $$ SELECT p.name FROM %[1]s.migrations p WHERE NOT EXISTS ( @@ -155,27 +156,28 @@ $$; CREATE OR REPLACE FUNCTION %[1]s.raw_migration() RETURNS event_trigger LANGUAGE plpgsql -SECURITY DEFINER AS $$ +SECURITY DEFINER +SET search_path = %[1]s, pg_catalog AS $$ DECLARE schemaname TEXT; BEGIN -- Ignore migrations done by pgroll - IF (current_setting('pgroll.internal', 'TRUE') <> 'TRUE') THEN + IF (pg_catalog.current_setting('pgroll.internal', 'TRUE') <> 'TRUE') THEN RETURN; END IF; IF tg_event = 'sql_drop' THEN -- Guess the schema from drop commands - SELECT schema_name INTO schemaname FROM pg_event_trigger_dropped_objects() WHERE schema_name IS NOT NULL; + SELECT schema_name INTO schemaname FROM pg_catalog.pg_event_trigger_dropped_objects() WHERE schema_name IS NOT NULL; ELSIF tg_event = 'ddl_command_end' THEN -- Guess the schema from ddl commands, ignore migrations that touch several schemas - IF (SELECT COUNT(DISTINCT schema_name) FROM pg_event_trigger_ddl_commands() WHERE schema_name IS NOT NULL) > 1 THEN + IF (SELECT COUNT(DISTINCT schema_name) FROM pg_catalog.pg_event_trigger_ddl_commands() WHERE schema_name IS NOT NULL) > 1 THEN RAISE NOTICE 'pgroll: ignoring migration that changes several schemas'; RETURN; END IF; - SELECT schema_name INTO schemaname FROM pg_event_trigger_ddl_commands() WHERE schema_name IS NOT NULL; + SELECT schema_name INTO schemaname FROM pg_catalog.pg_event_trigger_ddl_commands() WHERE schema_name IS NOT NULL; END IF; IF schemaname IS NULL THEN @@ -194,7 +196,7 @@ BEGIN VALUES ( schemaname, format('sql_%%s', substr(md5(random()::text), 0, 15)), - json_build_object('sql', json_build_object('up', current_query())), + pg_catalog.json_build_object('sql', pg_catalog.json_build_object('up', pg_catalog.current_query())), %[1]s.read_schema(schemaname), true, %[1]s.latest_version(schemaname) From 4d4442998593946daace1a95f2b701bda19e9182 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Carlos=20P=C3=A9rez-Aradros=20Herce?= Date: Tue, 24 Oct 2023 16:05:16 +0200 Subject: [PATCH 4/6] add pg_temp to the search path --- pkg/state/state.go | 6 +++--- 1 file changed, 3 insertions(+), 3 deletions(-) diff --git a/pkg/state/state.go b/pkg/state/state.go index f2ffe4b4..a32b82ad 100644 --- a/pkg/state/state.go +++ b/pkg/state/state.go @@ -52,7 +52,7 @@ CREATE OR REPLACE FUNCTION %[1]s.is_active_migration_period(schemaname NAME) RET -- Get the latest version name (this is the one with child migrations) CREATE OR REPLACE FUNCTION %[1]s.latest_version(schemaname NAME) RETURNS text SECURITY DEFINER -SET search_path = %[1]s, pg_catalog +SET search_path = %[1]s, pg_catalog, pg_temp AS $$ SELECT p.name FROM %[1]s.migrations p WHERE NOT EXISTS ( @@ -157,7 +157,7 @@ $$; CREATE OR REPLACE FUNCTION %[1]s.raw_migration() RETURNS event_trigger LANGUAGE plpgsql SECURITY DEFINER -SET search_path = %[1]s, pg_catalog AS $$ +SET search_path = %[1]s, pg_catalog, pg_temp AS $$ DECLARE schemaname TEXT; BEGIN @@ -195,7 +195,7 @@ BEGIN INSERT INTO %[1]s.migrations (schema, name, migration, resulting_schema, done, parent) VALUES ( schemaname, - format('sql_%%s', substr(md5(random()::text), 0, 15)), + pg_catalog.format('sql_%%s',pg_catalog.substr(md5(random()::text), 0, 15)), pg_catalog.json_build_object('sql', pg_catalog.json_build_object('up', pg_catalog.current_query())), %[1]s.read_schema(schemaname), true, From bd7505f2eab9fa908d052b06e095d2e38388e2f5 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Carlos=20P=C3=A9rez-Aradros=20Herce?= Date: Tue, 24 Oct 2023 16:06:13 +0200 Subject: [PATCH 5/6] count too --- pkg/state/state.go | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/pkg/state/state.go b/pkg/state/state.go index a32b82ad..c1ee9a0b 100644 --- a/pkg/state/state.go +++ b/pkg/state/state.go @@ -172,7 +172,7 @@ BEGIN ELSIF tg_event = 'ddl_command_end' THEN -- Guess the schema from ddl commands, ignore migrations that touch several schemas - IF (SELECT COUNT(DISTINCT schema_name) FROM pg_catalog.pg_event_trigger_ddl_commands() WHERE schema_name IS NOT NULL) > 1 THEN + IF (SELECT pg_catalog.count(DISTINCT schema_name) FROM pg_catalog.pg_event_trigger_ddl_commands() WHERE schema_name IS NOT NULL) > 1 THEN RAISE NOTICE 'pgroll: ignoring migration that changes several schemas'; RETURN; END IF; From b7830a34e2a510bec5037cf82930be6e31ab0392 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Carlos=20P=C3=A9rez-Aradros=20Herce?= Date: Wed, 25 Oct 2023 09:47:31 +0200 Subject: [PATCH 6/6] namespace random and md5 --- pkg/state/state.go | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/pkg/state/state.go b/pkg/state/state.go index c1ee9a0b..a169745d 100644 --- a/pkg/state/state.go +++ b/pkg/state/state.go @@ -195,7 +195,7 @@ BEGIN INSERT INTO %[1]s.migrations (schema, name, migration, resulting_schema, done, parent) VALUES ( schemaname, - pg_catalog.format('sql_%%s',pg_catalog.substr(md5(random()::text), 0, 15)), + pg_catalog.format('sql_%%s',pg_catalog.substr(pg_catalog.md5(pg_catalog.random()::text), 0, 15)), pg_catalog.json_build_object('sql', pg_catalog.json_build_object('up', pg_catalog.current_query())), %[1]s.read_schema(schemaname), true,