Skip to content

Commit a906776

Browse files
Recreate event trigger first in init.sql (#948)
Move event trigger creation to be the first thing that happens (after `pgroll` schema creation) in `init.sql`. Previous versions of `pgroll` used an event trigger that was incompatible with the latest version, causing errors on the upgrade path to `pgroll 0.14`. By moving event trigger creation to happen first during `init`, we ensure that the old event trigger installed by an older version of `pgroll` can't fire during the `init` of the new version.
1 parent 0c66cb0 commit a906776

File tree

1 file changed

+119
-119
lines changed

1 file changed

+119
-119
lines changed

pkg/state/init.sql

Lines changed: 119 additions & 119 deletions
Original file line numberDiff line numberDiff line change
@@ -1,6 +1,125 @@
11
-- SPDX-License-Identifier: Apache-2.0
22
CREATE SCHEMA IF NOT EXISTS placeholder;
33

4+
CREATE OR REPLACE FUNCTION placeholder.raw_migration ()
5+
RETURNS event_trigger
6+
LANGUAGE plpgsql
7+
SECURITY DEFINER
8+
SET search_path = placeholder, pg_catalog, pg_temp
9+
AS $$
10+
DECLARE
11+
schemaname text;
12+
migration_id text;
13+
BEGIN
14+
-- Ignore schema changes made by pgroll
15+
IF (pg_catalog.current_setting('pgroll.no_inferred_migrations', TRUE) = 'TRUE') THEN
16+
RETURN;
17+
END IF;
18+
IF tg_event = 'sql_drop' AND tg_tag = 'DROP SCHEMA' THEN
19+
-- Take the schema name from the drop schema command
20+
SELECT
21+
object_identity INTO schemaname
22+
FROM
23+
pg_event_trigger_dropped_objects ();
24+
ELSIF tg_event = 'sql_drop'
25+
AND tg_tag != 'ALTER TABLE' THEN
26+
-- Guess the schema from drop commands
27+
SELECT
28+
schema_name INTO schemaname
29+
FROM
30+
pg_catalog.pg_event_trigger_dropped_objects ()
31+
WHERE
32+
schema_name IS NOT NULL;
33+
ELSIF tg_event = 'ddl_command_end' THEN
34+
-- Guess the schema from ddl commands, ignore migrations that touch several schemas
35+
IF (
36+
SELECT
37+
pg_catalog.count(DISTINCT schema_name)
38+
FROM
39+
pg_catalog.pg_event_trigger_ddl_commands ()
40+
WHERE
41+
schema_name IS NOT NULL) > 1 THEN
42+
RETURN;
43+
END IF;
44+
IF tg_tag = 'CREATE SCHEMA' THEN
45+
SELECT
46+
object_identity INTO schemaname
47+
FROM
48+
pg_event_trigger_ddl_commands ();
49+
ELSE
50+
SELECT
51+
schema_name INTO schemaname
52+
FROM
53+
pg_catalog.pg_event_trigger_ddl_commands ()
54+
WHERE
55+
schema_name IS NOT NULL;
56+
END IF;
57+
END IF;
58+
IF schemaname IS NULL THEN
59+
RETURN;
60+
END IF;
61+
-- Ignore migrations done during a migration period
62+
IF placeholder.is_active_migration_period (schemaname) THEN
63+
RETURN;
64+
END IF;
65+
-- Remove any duplicate inferred migrations with the same timestamp for this
66+
-- schema. We assume such migrations are multi-statement batched migrations
67+
-- and we are only interested in the last one in the batch.
68+
DELETE FROM placeholder.migrations
69+
WHERE SCHEMA = schemaname
70+
AND created_at = CURRENT_TIMESTAMP
71+
AND migration_type = 'inferred'
72+
AND migration -> 'operations' -> 0 -> 'sql' ->> 'up' = current_query();
73+
-- Someone did a schema change without pgroll, include it in the history
74+
-- Get the latest non-inferred migration name with microsecond timestamp for ordering
75+
WITH latest_non_inferred AS (
76+
SELECT
77+
name
78+
FROM
79+
placeholder.migrations
80+
WHERE
81+
SCHEMA = schemaname
82+
AND migration_type != 'inferred'
83+
ORDER BY
84+
created_at DESC
85+
LIMIT 1
86+
)
87+
SELECT
88+
INTO migration_id CASE WHEN EXISTS (
89+
SELECT
90+
1
91+
FROM
92+
latest_non_inferred) THEN
93+
pg_catalog.format('%s_%s', (
94+
SELECT
95+
name
96+
FROM latest_non_inferred), pg_catalog.to_char(pg_catalog.clock_timestamp(), 'YYYYMMDDHH24MISSUS'))
97+
ELSE
98+
pg_catalog.format('00000_initial_%s', pg_catalog.to_char(pg_catalog.clock_timestamp(), 'YYYYMMDDHH24MISSUS'))
99+
END;
100+
INSERT INTO placeholder.migrations (schema, name, migration, resulting_schema, done, parent, migration_type, created_at, updated_at)
101+
VALUES (schemaname, migration_id, pg_catalog.json_build_object('version_schema', 'sql_' || substring(md5(random()::text), 1, 8), 'operations', (
102+
SELECT
103+
pg_catalog.json_agg(pg_catalog.json_build_object('sql', pg_catalog.json_build_object('up', pg_catalog.current_query()))))),
104+
placeholder.read_schema (schemaname),
105+
TRUE,
106+
placeholder.latest_migration (schemaname),
107+
'inferred',
108+
statement_timestamp(),
109+
statement_timestamp());
110+
END;
111+
$$;
112+
113+
DROP EVENT TRIGGER IF EXISTS pg_roll_handle_ddl;
114+
115+
CREATE EVENT TRIGGER pg_roll_handle_ddl ON ddl_command_end
116+
EXECUTE FUNCTION placeholder.raw_migration ();
117+
118+
DROP EVENT TRIGGER IF EXISTS pg_roll_handle_drop;
119+
120+
CREATE EVENT TRIGGER pg_roll_handle_drop ON sql_drop
121+
EXECUTE FUNCTION placeholder.raw_migration ();
122+
4123
CREATE TABLE IF NOT EXISTS placeholder.migrations (
5124
schema NAME NOT NULL,
6125
name text NOT NULL,
@@ -359,122 +478,3 @@ BEGIN
359478
END;
360479
$$;
361480

362-
CREATE OR REPLACE FUNCTION placeholder.raw_migration ()
363-
RETURNS event_trigger
364-
LANGUAGE plpgsql
365-
SECURITY DEFINER
366-
SET search_path = placeholder, pg_catalog, pg_temp
367-
AS $$
368-
DECLARE
369-
schemaname text;
370-
migration_id text;
371-
BEGIN
372-
-- Ignore schema changes made by pgroll
373-
IF (pg_catalog.current_setting('pgroll.no_inferred_migrations', TRUE) = 'TRUE') THEN
374-
RETURN;
375-
END IF;
376-
IF tg_event = 'sql_drop' AND tg_tag = 'DROP SCHEMA' THEN
377-
-- Take the schema name from the drop schema command
378-
SELECT
379-
object_identity INTO schemaname
380-
FROM
381-
pg_event_trigger_dropped_objects ();
382-
ELSIF tg_event = 'sql_drop'
383-
AND tg_tag != 'ALTER TABLE' THEN
384-
-- Guess the schema from drop commands
385-
SELECT
386-
schema_name INTO schemaname
387-
FROM
388-
pg_catalog.pg_event_trigger_dropped_objects ()
389-
WHERE
390-
schema_name IS NOT NULL;
391-
ELSIF tg_event = 'ddl_command_end' THEN
392-
-- Guess the schema from ddl commands, ignore migrations that touch several schemas
393-
IF (
394-
SELECT
395-
pg_catalog.count(DISTINCT schema_name)
396-
FROM
397-
pg_catalog.pg_event_trigger_ddl_commands ()
398-
WHERE
399-
schema_name IS NOT NULL) > 1 THEN
400-
RETURN;
401-
END IF;
402-
IF tg_tag = 'CREATE SCHEMA' THEN
403-
SELECT
404-
object_identity INTO schemaname
405-
FROM
406-
pg_event_trigger_ddl_commands ();
407-
ELSE
408-
SELECT
409-
schema_name INTO schemaname
410-
FROM
411-
pg_catalog.pg_event_trigger_ddl_commands ()
412-
WHERE
413-
schema_name IS NOT NULL;
414-
END IF;
415-
END IF;
416-
IF schemaname IS NULL THEN
417-
RETURN;
418-
END IF;
419-
-- Ignore migrations done during a migration period
420-
IF placeholder.is_active_migration_period (schemaname) THEN
421-
RETURN;
422-
END IF;
423-
-- Remove any duplicate inferred migrations with the same timestamp for this
424-
-- schema. We assume such migrations are multi-statement batched migrations
425-
-- and we are only interested in the last one in the batch.
426-
DELETE FROM placeholder.migrations
427-
WHERE SCHEMA = schemaname
428-
AND created_at = CURRENT_TIMESTAMP
429-
AND migration_type = 'inferred'
430-
AND migration -> 'operations' -> 0 -> 'sql' ->> 'up' = current_query();
431-
-- Someone did a schema change without pgroll, include it in the history
432-
-- Get the latest non-inferred migration name with microsecond timestamp for ordering
433-
WITH latest_non_inferred AS (
434-
SELECT
435-
name
436-
FROM
437-
placeholder.migrations
438-
WHERE
439-
SCHEMA = schemaname
440-
AND migration_type != 'inferred'
441-
ORDER BY
442-
created_at DESC
443-
LIMIT 1
444-
)
445-
SELECT
446-
INTO migration_id CASE WHEN EXISTS (
447-
SELECT
448-
1
449-
FROM
450-
latest_non_inferred) THEN
451-
pg_catalog.format('%s_%s', (
452-
SELECT
453-
name
454-
FROM latest_non_inferred), pg_catalog.to_char(pg_catalog.clock_timestamp(), 'YYYYMMDDHH24MISSUS'))
455-
ELSE
456-
pg_catalog.format('00000_initial_%s', pg_catalog.to_char(pg_catalog.clock_timestamp(), 'YYYYMMDDHH24MISSUS'))
457-
END;
458-
INSERT INTO placeholder.migrations (schema, name, migration, resulting_schema, done, parent, migration_type, created_at, updated_at)
459-
VALUES (schemaname, migration_id, pg_catalog.json_build_object('version_schema', 'sql_' || substring(md5(random()::text), 1, 8), 'operations', (
460-
SELECT
461-
pg_catalog.json_agg(pg_catalog.json_build_object('sql', pg_catalog.json_build_object('up', pg_catalog.current_query()))))),
462-
placeholder.read_schema (schemaname),
463-
TRUE,
464-
placeholder.latest_migration (schemaname),
465-
'inferred',
466-
statement_timestamp(),
467-
statement_timestamp());
468-
END;
469-
$$;
470-
471-
DROP EVENT TRIGGER IF EXISTS pg_roll_handle_ddl;
472-
473-
CREATE EVENT TRIGGER pg_roll_handle_ddl ON ddl_command_end
474-
EXECUTE FUNCTION placeholder.raw_migration ();
475-
476-
DROP EVENT TRIGGER IF EXISTS pg_roll_handle_drop;
477-
478-
CREATE EVENT TRIGGER pg_roll_handle_drop ON sql_drop
479-
EXECUTE FUNCTION placeholder.raw_migration ();
480-

0 commit comments

Comments
 (0)