Skip to content

Commit

Permalink
Block the emaj extension installation or upgrade on postgres versions…
Browse files Browse the repository at this point in the history
… prior V11. In regression test scenarios, when creating the emaj extension, use the CASCADE clause and remove the explicit btree_gist and dblink extensions creation. In the setup.sql and create_drop.sql regression test scripts, remove some now useless object creations and manipulations that were needed for PG10-.
  • Loading branch information
beaud76 committed Feb 17, 2023
1 parent 46c0429 commit b3b3c47
Show file tree
Hide file tree
Showing 33 changed files with 175 additions and 264 deletions.
1 change: 1 addition & 0 deletions CHANGES.md
Original file line number Diff line number Diff line change
Expand Up @@ -3,6 +3,7 @@ E-Maj - Change log
<devel>
------
###Enhancements:###
* Remove the support of postgres versions prior V11.
* Minor code changes.

###Bug fixes:###
Expand Down
86 changes: 79 additions & 7 deletions sql/emaj--4.1.0--devel.sql
Original file line number Diff line number Diff line change
Expand Up @@ -31,27 +31,31 @@ $do$
IF v_emajVersion <> '4.1.0' THEN
RAISE EXCEPTION 'E-Maj upgrade: the current E-Maj version (%) is not 4.1.0',v_emajVersion;
END IF;
-- The installed postgres version must be at least 9.5.
IF current_setting('server_version_num')::int < 90500 THEN
RAISE EXCEPTION 'E-Maj upgrade: the current PostgreSQL version (%) is not compatible with the new E-Maj version. The PostgreSQL version should be at least 9.5.', current_setting('server_version');
-- The installed postgres version must be at least 11.
IF current_setting('server_version_num')::int < 110000 THEN
RAISE EXCEPTION 'E-Maj upgrade: the current PostgreSQL version (%) is not compatible with the new E-Maj version. The PostgreSQL '
'version should be at least 11.', current_setting('server_version');
END IF;
-- Check E-Maj environment state.
SELECT count(msg) FILTER (WHERE msg = 'No error detected'),
count(msg) FILTER (WHERE msg LIKE 'Warning:%')
INTO v_nbNoError, v_nbWarning
FROM emaj.emaj_verify_all() AS t(msg);
IF v_nbNoError = 0 THEN
RAISE EXCEPTION 'E-Maj upgrade: the E-Maj environment is damaged. Please fix the issue before upgrading. You may execute "SELECT * FROM emaj.emaj_verify_all();" to get more details.';
RAISE EXCEPTION 'E-Maj upgrade: the E-Maj environment is damaged. Please fix the issue before upgrading. You may execute '
'"SELECT * FROM emaj.emaj_verify_all();" to get more details.';
END IF;
IF v_nbWarning > 0 THEN
RAISE WARNING 'E-Maj upgrade: the E-Maj environment health check reports warning. You may execute "SELECT * FROM emaj.emaj_verify_all();" to get more details.';
RAISE WARNING 'E-Maj upgrade: the E-Maj environment health check reports warning. You may execute "SELECT * FROM '
'emaj.emaj_verify_all();" to get more details.';
END IF;
-- No existing group must have been created with a postgres version prior 8.4.
SELECT string_agg(group_name, ', ') INTO v_groupList FROM emaj.emaj_group
WHERE cast(to_number(substring(group_pg_version FROM E'^(\\d+)'),'99') * 100 +
to_number(substring(group_pg_version FROM E'^\\d+\\.(\\d+)'),'99') AS INTEGER) < 804;
IF v_groupList IS NOT NULL THEN
RAISE EXCEPTION 'E-Maj upgrade: groups "%" have been created with a too old postgres version (< 8.4). Drop these groups before upgrading. ',v_groupList;
RAISE EXCEPTION 'E-Maj upgrade: groups "%" have been created with a too old postgres version (< 8.4). Drop these groups before '
'upgrading. ',v_groupList;
END IF;
END;
$do$;
Expand Down Expand Up @@ -1300,6 +1304,73 @@ $_rlbk_end$
END;
$_rlbk_end$;

CREATE OR REPLACE FUNCTION emaj.emaj_verify_all()
RETURNS SETOF TEXT LANGUAGE plpgsql AS
$emaj_verify_all$
-- The function verifies the consistency between all emaj objects present inside emaj schema and
-- emaj objects related to tables and sequences referenced in the emaj_relation table.
-- It returns a set of warning messages for discovered discrepancies. If no error is detected, a single row is returned.
DECLARE
v_errorFound BOOLEAN = FALSE;
v_nbMissingEventTrigger INT;
r_object RECORD;
BEGIN
-- Global checks.
-- Detect if the current postgres version is at least 11.
IF emaj._pg_version_num() < 110000 THEN
RETURN NEXT 'Error: The current postgres version (' || version()
|| ') is not compatible with this E-Maj version. It should be at least 11';
v_errorFound = TRUE;
END IF;
-- Check all E-Maj schemas.
FOR r_object IN
SELECT msg
FROM emaj._verify_all_schemas() msg
LOOP
RETURN NEXT r_object.msg;
IF r_object.msg LIKE 'Error%' THEN
v_errorFound = TRUE;
END IF;
END LOOP;
-- Check all groups components.
FOR r_object IN
SELECT msg
FROM emaj._verify_all_groups() msg
LOOP
RETURN NEXT r_object.msg;
IF r_object.msg LIKE 'Error%' THEN
v_errorFound = TRUE;
END IF;
END LOOP;
-- Report a warning if some E-Maj event triggers are missing.
SELECT 3 - count(*) INTO v_nbMissingEventTrigger
FROM pg_catalog.pg_event_trigger
WHERE evtname IN ('emaj_protection_trg','emaj_sql_drop_trg','emaj_table_rewrite_trg');
IF v_nbMissingEventTrigger > 0 THEN
RETURN NEXT 'Warning: Some E-Maj event triggers are missing. Your database administrator may (re)create them using the'
|| ' emaj_upgrade_after_postgres_upgrade.sql script.';
END IF;
-- Report a warning if some E-Maj event triggers exist but are not enabled.
IF EXISTS
(SELECT 0
FROM pg_catalog.pg_event_trigger
WHERE evtname LIKE 'emaj%'
AND evtenabled = 'D'
) THEN
RETURN NEXT 'Warning: Some E-Maj event triggers exist but are disabled. You may enable them using the'
|| ' emaj_enable_protection_by_event_triggers() function.';
END IF;
-- Final message if no error has been yet detected.
IF NOT v_errorFound THEN
RETURN NEXT 'No error detected';
END IF;
--
RETURN;
END;
$emaj_verify_all$;
COMMENT ON FUNCTION emaj.emaj_verify_all() IS
$$Verifies the consistency between existing E-Maj and application objects.$$;

--<end_functions> pattern used by the tool that extracts and insert the functions definition
------------------------------------------
-- --
Expand Down Expand Up @@ -1376,7 +1447,8 @@ $tmp$
BEGIN
-- Check the max_prepared_transactions GUC value.
IF current_setting('max_prepared_transactions')::int <= 1 THEN
RAISE WARNING 'E-Maj upgrade: as the max_prepared_transactions parameter value (%) on this cluster is too low, no parallel rollback is possible.', current_setting('max_prepared_transactions');
RAISE WARNING 'E-Maj upgrade: as the max_prepared_transactions parameter value (%) on this cluster is too low, no parallel rollback '
'is possible.', current_setting('max_prepared_transactions');
END IF;
END;
$tmp$;
Expand Down
14 changes: 7 additions & 7 deletions sql/emaj--devel.sql
Original file line number Diff line number Diff line change
Expand Up @@ -13,15 +13,15 @@
-- The emaj extension also installs the dblink and btree_gist extensions into the database if they are not already installed.

-- Complain if this script is executed in psql, rather than via a CREATE EXTENSION statement.
\echo Use "CREATE EXTENSION emaj" to install the E-Maj extension. \quit
\echo Use "CREATE EXTENSION emaj CASCADE" to install the E-Maj extension. \quit

-- Perform some checks and create emaj roles.
DO LANGUAGE plpgsql
$do$
BEGIN
-- Check postgres version is >= 9.5.
IF current_setting('server_version_num')::INT < 90500 THEN
RAISE EXCEPTION 'E-Maj installation: The current postgres version (%) is too old for this E-Maj version. It should be at least 9.5.',
-- Check postgres version is >= 11.
IF current_setting('server_version_num')::INT < 110000 THEN
RAISE EXCEPTION 'E-Maj installation: The current postgres version (%) is too old for this E-Maj version. It should be at least 11.',
current_setting('server_version');
END IF;
-- Create both emaj_adm and emaj_viewer roles (NOLOGIN), if they do not exist.
Expand Down Expand Up @@ -12054,10 +12054,10 @@ $emaj_verify_all$
r_object RECORD;
BEGIN
-- Global checks.
-- Detect if the current postgres version is at least 9.5.
IF emaj._pg_version_num() < 90500 THEN
-- Detect if the current postgres version is at least 11.
IF emaj._pg_version_num() < 110000 THEN
RETURN NEXT 'Error: The current postgres version (' || version()
|| ') is not compatible with this E-Maj version. It should be at least 9.5.';
|| ') is not compatible with this E-Maj version. It should be at least 11';
v_errorFound = TRUE;
END IF;
-- Check all E-Maj schemas.
Expand Down
12 changes: 6 additions & 6 deletions sql/emaj-devel.sql
Original file line number Diff line number Diff line change
Expand Up @@ -19,9 +19,9 @@
DO LANGUAGE plpgsql
$do$
BEGIN
-- Check postgres version is >= 9.5.
IF current_setting('server_version_num')::INT < 90500 THEN
RAISE EXCEPTION 'E-Maj installation: The current postgres version (%) is too old for this E-Maj version. It should be at least 9.5.',
-- Check postgres version is >= 11.
IF current_setting('server_version_num')::INT < 110000 THEN
RAISE EXCEPTION 'E-Maj installation: The current postgres version (%) is too old for this E-Maj version. It should be at least 11.',
current_setting('server_version');
END IF;
-- Create both emaj_adm and emaj_viewer roles (NOLOGIN), if they do not exist.
Expand Down Expand Up @@ -12061,10 +12061,10 @@ $emaj_verify_all$
r_object RECORD;
BEGIN
-- Global checks.
-- Detect if the current postgres version is at least 9.5.
IF emaj._pg_version_num() < 90500 THEN
-- Detect if the current postgres version is at least 11.
IF emaj._pg_version_num() < 110000 THEN
RETURN NEXT 'Error: The current postgres version (' || version()
|| ') is not compatible with this E-Maj version. It should be at least 9.5.';
|| ') is not compatible with this E-Maj version. It should be at least 11';
v_errorFound = TRUE;
END IF;
-- Check all E-Maj schemas.
Expand Down
9 changes: 2 additions & 7 deletions test/11/expected/create_drop.out
Original file line number Diff line number Diff line change
Expand Up @@ -148,7 +148,7 @@ select emaj.emaj_assign_table('myschema1','dummyTable','myGroup1');
ERROR: _assign_tables: In schema myschema1, some tables ("dummyTable") do not exist.
CONTEXT: PL/pgSQL function emaj._assign_tables(text,text[],text,jsonb,text,boolean,boolean) line 78 at RAISE
PL/pgSQL function emaj.emaj_assign_table(text,text,text,jsonb,text) line 7 at RETURN
-- partitionned table (successful with PG9.6- versions)
-- partitionned table
select emaj.emaj_assign_table('myschema4','mytblp','myGroup1');
ERROR: _assign_tables: In schema myschema4, some tables (mytblp) are partitionned tables (only elementary partitions are supported by E-Maj).
CONTEXT: PL/pgSQL function emaj._assign_tables(text,text[],text,jsonb,text,boolean,boolean) line 90 at RAISE
Expand Down Expand Up @@ -485,7 +485,7 @@ WARNING: _assign_tables: No table to process.
(1 row)

-- excluded tables
-- bad types (partitionned table is successful with PG9.6- versions)
-- bad types
select emaj.emaj_assign_tables('myschema4','mytblp$','','myGroup2');
WARNING: _assign_tables: Some partitionned tables (mytblp) are not selected.
WARNING: _assign_tables: No table to process.
Expand All @@ -503,11 +503,6 @@ WARNING: _assign_tables: No table to process.
0
(1 row)

-- partitionned table is successful with PG9.6- versions, so remove it
select emaj.emaj_remove_table('myschema4','mytblp');
ERROR: _remove_tables: some tables (myschema4.mytblp) do not currently belong to any tables group.
CONTEXT: PL/pgSQL function emaj._remove_tables(text,text[],text,boolean,boolean) line 49 at RAISE
PL/pgSQL function emaj.emaj_remove_table(text,text,text) line 6 at RETURN
-- the myoidstbl table is removed with PG12+: in these version the myoids table has no OIDS as this propertiy doesn't exist anymore
select emaj.emaj_remove_table('myschema5','myoidstbl');
ERROR: _remove_tables: some tables (myschema5.myoidstbl) do not currently belong to any tables group.
Expand Down
11 changes: 4 additions & 7 deletions test/11/expected/install.out
Original file line number Diff line number Diff line change
@@ -1,14 +1,11 @@
-- install.sql : install E-Maj as an extension (for postgres version 9.1+)
-- install.sql : install E-Maj as an extension
--
-----------------------------
-- install dblink and btree_gist
-----------------------------
CREATE EXTENSION IF NOT EXISTS dblink;
CREATE EXTENSION IF NOT EXISTS btree_gist;
-----------------------------
-- emaj installation as extension
-----------------------------
CREATE EXTENSION emaj VERSION 'devel';
CREATE EXTENSION emaj VERSION 'devel' CASCADE;
NOTICE: installing required extension "dblink"
NOTICE: installing required extension "btree_gist"
-----------------------------
-- verify that dropping the extension is blocked by event trigger
-----------------------------
Expand Down
9 changes: 3 additions & 6 deletions test/11/expected/install_upgrade.out
Original file line number Diff line number Diff line change
Expand Up @@ -2,11 +2,6 @@
-- Install the last stable E-Maj version and immediately upgrade to the devel version, while groups are not yet created.
-- install E-Maj as an extension
--
------------------------------------------------------------
-- install dblink and btree_gist
------------------------------------------------------------
CREATE EXTENSION IF NOT EXISTS dblink;
CREATE EXTENSION IF NOT EXISTS btree_gist;
-----------------------------
-- check the extension's availability
-----------------------------
Expand Down Expand Up @@ -407,7 +402,9 @@ select * from pg_extension_update_paths('emaj') order by 1,2;;
-----------------------------------------------------------
-- emaj update to next_version
-----------------------------------------------------------
CREATE EXTENSION emaj VERSION '4.1.0';
CREATE EXTENSION emaj VERSION '4.1.0' CASCADE;
NOTICE: installing required extension "dblink"
NOTICE: installing required extension "btree_gist"
-- check impact in catalog
select extname, extversion from pg_extension where extname = 'emaj';
extname | extversion
Expand Down
18 changes: 1 addition & 17 deletions test/11/expected/setup.out
Original file line number Diff line number Diff line change
Expand Up @@ -248,28 +248,12 @@ CREATE TABLE myTblP (
col2 TEXT,
col3 SERIAL
) PARTITION BY RANGE (col1);
-- create the table with PG 9.6- so that next scripts work
CREATE TABLE IF NOT EXISTS myTblP (
col1 INT NOT NULL,
col2 TEXT,
col3 SERIAL
);
-- add a global PK (will fail with PG10 & PG11)
-- add a global PK
ALTER TABLE myTblP ADD PRIMARY KEY (col1);
DROP TABLE IF EXISTS myPartP1;
CREATE TABLE myPartP1 PARTITION OF myTblP FOR VALUES FROM (MINVALUE) TO (0);
-- create the table with PG 9.6- so that next scripts do not abort
CREATE TABLE IF NOT EXISTS myPartP1 () INHERITS (myTblP);
-- add a PK (will fail with PG10+ because of the global PK)
ALTER TABLE myPartP1 ADD PRIMARY KEY (col1);
ERROR: multiple primary keys for table "mypartp1" are not allowed
DROP TABLE IF EXISTS myPartP2;
CREATE TABLE myPartP2 PARTITION OF myTblP FOR VALUES FROM (0) TO (9);
-- create the table with PG 9.6- so that next scripts do not abort
CREATE TABLE IF NOT EXISTS myPartP2 () INHERITS (myTblP);
-- add a PK (will fail with PG10+ because of the global PK)
ALTER TABLE myPartP2 ADD PRIMARY KEY (col1);
ERROR: multiple primary keys for table "mypartp2" are not allowed
DROP TABLE IF EXISTS myTblR ;
CREATE TABLE myTblR (
col1 SERIAL NOT NULL PRIMARY KEY,
Expand Down
9 changes: 2 additions & 7 deletions test/12/expected/create_drop.out
Original file line number Diff line number Diff line change
Expand Up @@ -148,7 +148,7 @@ select emaj.emaj_assign_table('myschema1','dummyTable','myGroup1');
ERROR: _assign_tables: In schema myschema1, some tables ("dummyTable") do not exist.
CONTEXT: PL/pgSQL function emaj._assign_tables(text,text[],text,jsonb,text,boolean,boolean) line 78 at RAISE
PL/pgSQL function emaj.emaj_assign_table(text,text,text,jsonb,text) line 7 at RETURN
-- partitionned table (successful with PG9.6- versions)
-- partitionned table
select emaj.emaj_assign_table('myschema4','mytblp','myGroup1');
ERROR: _assign_tables: In schema myschema4, some tables (mytblp) are partitionned tables (only elementary partitions are supported by E-Maj).
CONTEXT: PL/pgSQL function emaj._assign_tables(text,text[],text,jsonb,text,boolean,boolean) line 90 at RAISE
Expand Down Expand Up @@ -489,7 +489,7 @@ WARNING: _assign_tables: No table to process.
(1 row)

-- excluded tables
-- bad types (partitionned table is successful with PG9.6- versions)
-- bad types
select emaj.emaj_assign_tables('myschema4','mytblp$','','myGroup2');
WARNING: _assign_tables: Some partitionned tables (mytblp) are not selected.
WARNING: _assign_tables: No table to process.
Expand All @@ -505,11 +505,6 @@ WARNING: _assign_tables: Some UNLOGGED tables (myunloggedtbl) are not selected.
1
(1 row)

-- partitionned table is successful with PG9.6- versions, so remove it
select emaj.emaj_remove_table('myschema4','mytblp');
ERROR: _remove_tables: some tables (myschema4.mytblp) do not currently belong to any tables group.
CONTEXT: PL/pgSQL function emaj._remove_tables(text,text[],text,boolean,boolean) line 49 at RAISE
PL/pgSQL function emaj.emaj_remove_table(text,text,text) line 6 at RETURN
-- the myoidstbl table is removed with PG12+: in these version the myoids table has no OIDS as this propertiy doesn't exist anymore
select emaj.emaj_remove_table('myschema5','myoidstbl');
emaj_remove_table
Expand Down
11 changes: 4 additions & 7 deletions test/12/expected/install.out
Original file line number Diff line number Diff line change
@@ -1,14 +1,11 @@
-- install.sql : install E-Maj as an extension (for postgres version 9.1+)
-- install.sql : install E-Maj as an extension
--
-----------------------------
-- install dblink and btree_gist
-----------------------------
CREATE EXTENSION IF NOT EXISTS dblink;
CREATE EXTENSION IF NOT EXISTS btree_gist;
-----------------------------
-- emaj installation as extension
-----------------------------
CREATE EXTENSION emaj VERSION 'devel';
CREATE EXTENSION emaj VERSION 'devel' CASCADE;
NOTICE: installing required extension "dblink"
NOTICE: installing required extension "btree_gist"
-----------------------------
-- verify that dropping the extension is blocked by event trigger
-----------------------------
Expand Down
9 changes: 3 additions & 6 deletions test/12/expected/install_previous.out
Original file line number Diff line number Diff line change
@@ -1,10 +1,5 @@
-- install_previous.sql : install previous version of E-Maj as an extension
--
------------------------------------------------------------
-- install dblink and btree_gist
------------------------------------------------------------
CREATE EXTENSION dblink;
CREATE EXTENSION btree_gist;
-----------------------------
-- set the default_tablespace parameter to tspemaj to store new technical tables into this tablespace
-----------------------------
Expand All @@ -13,7 +8,9 @@ SET default_tablespace TO tspemaj;
------------------------------------------------------------
-- emaj installation in its previous version as an extension
------------------------------------------------------------
CREATE EXTENSION emaj VERSION '4.1.0';
CREATE EXTENSION emaj VERSION '4.1.0' CASCADE;
NOTICE: installing required extension "dblink"
NOTICE: installing required extension "btree_gist"
------------------------------------------------------------
-- check installation
------------------------------------------------------------
Expand Down
9 changes: 3 additions & 6 deletions test/12/expected/install_upgrade.out
Original file line number Diff line number Diff line change
Expand Up @@ -2,11 +2,6 @@
-- Install the last stable E-Maj version and immediately upgrade to the devel version, while groups are not yet created.
-- install E-Maj as an extension
--
------------------------------------------------------------
-- install dblink and btree_gist
------------------------------------------------------------
CREATE EXTENSION IF NOT EXISTS dblink;
CREATE EXTENSION IF NOT EXISTS btree_gist;
-----------------------------
-- check the extension's availability
-----------------------------
Expand Down Expand Up @@ -407,7 +402,9 @@ select * from pg_extension_update_paths('emaj') order by 1,2;;
-----------------------------------------------------------
-- emaj update to next_version
-----------------------------------------------------------
CREATE EXTENSION emaj VERSION '4.1.0';
CREATE EXTENSION emaj VERSION '4.1.0' CASCADE;
NOTICE: installing required extension "dblink"
NOTICE: installing required extension "btree_gist"
-- check impact in catalog
select extname, extversion from pg_extension where extname = 'emaj';
extname | extversion
Expand Down

0 comments on commit b3b3c47

Please sign in to comment.