-- -- E-Maj: migration from 4.0.0 to 4.0.1 -- -- This software is distributed under the GNU General Public License. -- -- This script upgrades an existing installation of E-Maj extension. -- -- Complain if this script is executed in psql, rather than via an ALTER EXTENSION statement. \echo Use "ALTER EXTENSION emaj UPDATE TO..." to upgrade the E-Maj extension. \quit --SET client_min_messages TO WARNING; SET client_min_messages TO NOTICE; ------------------------------------ -- -- -- checks -- -- -- ------------------------------------ -- Check that the upgrade conditions are met. DO $do$ DECLARE v_emajVersion TEXT; v_txid TEXT; v_nbNoError INT; v_nbWarning INT; v_groupList TEXT; BEGIN -- The emaj version registered in emaj_param must be '4.0.0'. SELECT param_value_text INTO v_emajVersion FROM emaj.emaj_param WHERE param_key = 'emaj_version'; IF v_emajVersion <> '4.0.0' THEN RAISE EXCEPTION 'E-Maj upgrade: the current E-Maj version (%) is not 4.0.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'); END IF; -- Check the E-Maj environment state, if not yet done by a previous upgrade in the same transaction. SELECT current_setting('emaj.upgrade_verify_txid', TRUE) INTO v_txid; IF v_txid IS NULL OR v_txid <> txid_current()::TEXT THEN BEGIN 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); EXCEPTION -- Errors during the emaj_verify_all() execution are trapped. The emaj_verify_all() code may be incompatible with the current PG version. WHEN OTHERS THEN -- do nothing END; 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. ' 'An "ALTER EXTENSION emaj UPDATE TO ''%'';" statement may be required before.', v_emajVersion; 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.'; END IF; IF v_nbWarning IS NOT NULL THEN PERFORM set_config('emaj.upgrade_verify_txid', txid_current()::TEXT, TRUE); END IF; 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; END IF; END; $do$; -- OK, the upgrade operation can start... -- Insert the upgrade begin record in the operation history. INSERT INTO emaj.emaj_hist (hist_function, hist_event, hist_object, hist_wording) VALUES ('EMAJ_INSTALL','BEGIN','E-Maj 4.0.1', 'Upgrade from 4.0.0 started'); -- Lock emaj_group table to avoid any concurrent E-Maj activity. LOCK TABLE emaj.emaj_group IN EXCLUSIVE MODE; -- Disable the event triggers during the upgrade operation. SELECT emaj._disable_event_triggers(); ---------------------------------------------- -- -- -- emaj enums, tables, views and sequences -- -- -- ---------------------------------------------- -- -- Add created or recreated tables and sequences to the list of content to save by pg_dump. -- ------------------------------------ -- -- -- emaj types -- -- -- ------------------------------------ ------------------------------------ -- -- -- emaj functions -- -- -- ------------------------------------ -- Recreate functions that have been previously dropped in the tables structure upgrade step and will not be recreated later in this script. -- pattern used by the tool that extracts and insert the functions definition ------------------------------------------------------------------ -- drop obsolete functions or functions with modified interface -- ------------------------------------------------------------------ ------------------------------------------------------------------ -- create new or modified functions -- ------------------------------------------------------------------ CREATE OR REPLACE FUNCTION emaj._check_fk_groups(p_groupNames TEXT[]) RETURNS VOID LANGUAGE plpgsql AS $_check_fk_groups$ -- This function checks foreign key constraints for tables of a groups array. -- Tables from audit_only groups are ignored in this check because they will never be rolled back. -- Input: group names array DECLARE r_fk RECORD; BEGIN -- Issue a warning if a table of the groups has a foreign key that references a table outside the groups. FOR r_fk IN SELECT c.conname,r.rel_schema,r.rel_tblseq,nf.nspname,tf.relname FROM emaj.emaj_relation r JOIN emaj.emaj_group g ON (g.group_name = r.rel_group) JOIN pg_catalog.pg_class t ON (t.relname = r.rel_tblseq) JOIN pg_catalog.pg_namespace n ON (t.relnamespace = n.oid AND n.nspname = r.rel_schema) JOIN pg_catalog.pg_constraint c ON (c.conrelid = t.oid) JOIN pg_catalog.pg_class tf ON (tf.oid = c.confrelid) JOIN pg_catalog.pg_namespace nf ON (nf.oid = tf.relnamespace) WHERE contype = 'f' -- FK constraints only AND upper_inf(r.rel_time_range) AND r.rel_group = ANY (p_groupNames) -- only tables currently belonging to the selected groups AND g.group_is_rollbackable -- only tables from rollbackable groups AND tf.relkind = 'r' -- only constraints referencing true tables, ie. excluding -- partitionned tables AND NOT EXISTS -- referenced table currently outside the groups (SELECT 0 FROM emaj.emaj_relation WHERE rel_schema = nf.nspname AND rel_tblseq = tf.relname AND upper_inf(rel_time_range) AND rel_group = ANY (p_groupNames) ) ORDER BY 1,2,3 LOOP RAISE WARNING '_check_fk_groups: The foreign key "%" on the table "%.%" references the table "%.%" that is outside the groups (%).', r_fk.conname,r_fk.rel_schema,r_fk.rel_tblseq,r_fk.nspname,r_fk.relname,array_to_string(p_groupNames,','); END LOOP; -- Issue a warning if a table of the groups is referenced by a table outside the groups. FOR r_fk IN SELECT c.conname,n.nspname,t.relname,r.rel_schema,r.rel_tblseq FROM emaj.emaj_relation r JOIN emaj.emaj_group g ON (g.group_name = r.rel_group) JOIN pg_catalog.pg_class tf ON (tf.relname = r.rel_tblseq) JOIN pg_catalog.pg_namespace nf ON (nf.oid = tf.relnamespace AND nf.nspname = r.rel_schema) JOIN pg_catalog.pg_constraint c ON (c.confrelid = tf.oid) JOIN pg_catalog.pg_class t ON (t.oid = c.conrelid) JOIN pg_catalog.pg_namespace n ON (n.oid = t.relnamespace) WHERE contype = 'f' -- FK constraints only AND upper_inf(r.rel_time_range) AND r.rel_group = ANY (p_groupNames) -- only tables currently belonging to the selected groups AND g.group_is_rollbackable -- only tables from rollbackable groups AND t.relkind = 'r' -- only constraints referenced by true tables, ie. excluding -- partitionned tables AND NOT EXISTS -- referenced table outside the groups (SELECT 0 FROM emaj.emaj_relation WHERE rel_schema = n.nspname AND rel_tblseq = t.relname AND upper_inf(rel_time_range) AND rel_group = ANY (p_groupNames) ) ORDER BY 1,2,3 LOOP RAISE WARNING '_check_fk_groups: The table "%.%" is referenced by the foreign key "%" on the table "%.%" that is outside' ' the groups (%).', r_fk.rel_schema, r_fk.rel_tblseq, r_fk.conname, r_fk.nspname, r_fk.relname, array_to_string(p_groupNames,','); END LOOP; -- RETURN; END; $_check_fk_groups$; CREATE OR REPLACE FUNCTION emaj._rlbk_init(p_groupNames TEXT[], p_mark TEXT, p_isLoggedRlbk BOOLEAN, p_nbSession INT, p_multiGroup BOOLEAN, p_isAlterGroupAllowed BOOLEAN DEFAULT FALSE) RETURNS INT LANGUAGE plpgsql AS $_rlbk_init$ -- This is the first step of a rollback group processing. -- It tests the environment, the supplied parameters and the foreign key constraints. -- By calling the _rlbk_planning() function, it defines the different elementary steps needed for the operation, -- and spread the load on the requested number of sessions. -- It returns a rollback id that will be needed by next steps (or NULL if there are some NULL input). -- This function may be directly called by the Emaj_web client. DECLARE v_markName TEXT; v_markTimeId BIGINT; v_markTimestamp TIMESTAMPTZ; v_nbTblInGroups INT; v_nbSeqInGroups INT; v_dbLinkCnxStatus INT; v_isDblinkUsed BOOLEAN; v_dbLinkSchema TEXT; v_effNbTable INT; v_histId BIGINT; v_stmt TEXT; v_rlbkId INT; BEGIN -- Check supplied group names and mark parameters. SELECT emaj._rlbk_check(p_groupNames, p_mark, p_isAlterGroupAllowed, FALSE) INTO v_markName; IF v_markName IS NOT NULL THEN -- Check that no group is damaged. PERFORM 0 FROM emaj._verify_groups(p_groupNames, TRUE); -- Get the time stamp id and its clock timestamp for the first group (as we know this time stamp is the same for all groups of the array). SELECT time_id, time_clock_timestamp INTO v_markTimeId, v_markTimestamp FROM emaj.emaj_mark JOIN emaj.emaj_time_stamp ON (time_id = mark_time_id) WHERE mark_group = p_groupNames[1] AND mark_name = v_markName; -- Insert a BEGIN event into the history. INSERT INTO emaj.emaj_hist (hist_function, hist_event, hist_object, hist_wording) VALUES (CASE WHEN p_multiGroup THEN 'ROLLBACK_GROUPS' ELSE 'ROLLBACK_GROUP' END, 'BEGIN', array_to_string(p_groupNames,','), CASE WHEN p_isLoggedRlbk THEN 'Logged' ELSE 'Unlogged' END || ' rollback to mark ' || v_markName || ' [' || v_markTimestamp || ']' ) RETURNING hist_id INTO v_histId; -- Get the total number of tables for these groups. SELECT sum(group_nb_table), sum(group_nb_sequence) INTO v_nbTblInGroups, v_nbSeqInGroups FROM emaj.emaj_group WHERE group_name = ANY (p_groupNames) ; -- First try to open a dblink connection. SELECT p_status, (p_status >= 0), CASE WHEN p_status >= 0 THEN p_schema ELSE NULL END INTO v_dbLinkCnxStatus, v_isDblinkUsed, v_dbLinkSchema FROM emaj._dblink_open_cnx('rlbk#1'); -- For parallel rollback (i.e. when nb sessions > 1), the dblink connection must be ok. IF p_nbSession > 1 AND NOT v_isDblinkUsed THEN RAISE EXCEPTION '_rlbk_init: Cannot use several sessions without dblink connection capability. (Status of the dblink' ' connection attempt = % - see E-Maj documentation)', v_dbLinkCnxStatus; END IF; -- Create the row representing the rollback event in the emaj_rlbk table and get the rollback id back. v_stmt = 'INSERT INTO emaj.emaj_rlbk (rlbk_groups, rlbk_mark, rlbk_mark_time_id, rlbk_is_logged, rlbk_is_alter_group_allowed, ' || 'rlbk_nb_session, rlbk_nb_table, rlbk_nb_sequence, rlbk_status, rlbk_begin_hist_id, ' || 'rlbk_dblink_schema, rlbk_is_dblink_used) ' || 'VALUES (' || quote_literal(p_groupNames) || ',' || quote_literal(v_markName) || ',' || v_markTimeId || ',' || p_isLoggedRlbk || ',' || quote_nullable(p_isAlterGroupAllowed) || ',' || p_nbSession || ',' || v_nbTblInGroups || ',' || v_nbSeqInGroups || ', ''PLANNING'',' || v_histId || ',' || quote_nullable(v_dbLinkSchema) || ',' || v_isDblinkUsed || ') RETURNING rlbk_id'; SELECT emaj._dblink_sql_exec('rlbk#1', v_stmt, v_dblinkSchema) INTO v_rlbkId; -- Create the session row the emaj_rlbk_session table. v_stmt = 'INSERT INTO emaj.emaj_rlbk_session (rlbs_rlbk_id, rlbs_session, rlbs_txid, rlbs_start_datetime) ' || 'VALUES (' || v_rlbkId || ', 1, ' || txid_current() || ',' || quote_literal(clock_timestamp()) || ') RETURNING 1'; PERFORM emaj._dblink_sql_exec('rlbk#1', v_stmt, v_dblinkSchema); -- Call the rollback planning function to define all the elementary steps to perform, compute their estimated duration -- and spread the elementary steps among sessions. v_stmt = 'SELECT emaj._rlbk_planning(' || v_rlbkId || ')'; SELECT emaj._dblink_sql_exec('rlbk#1', v_stmt, v_dblinkSchema) INTO v_effNbTable; -- Update the emaj_rlbk table to set the real number of tables to process and adjust the rollback status. v_stmt = 'UPDATE emaj.emaj_rlbk SET rlbk_eff_nb_table = ' || v_effNbTable || ', rlbk_status = ''LOCKING'' ' || ' WHERE rlbk_id = ' || v_rlbkId || ' RETURNING 1'; PERFORM emaj._dblink_sql_exec('rlbk#1', v_stmt, v_dblinkSchema); END IF; -- RETURN v_rlbkId; END; $_rlbk_init$; CREATE OR REPLACE FUNCTION emaj._rlbk_planning(p_rlbkId INT) RETURNS INT LANGUAGE plpgsql SECURITY DEFINER SET search_path = pg_catalog, pg_temp AS $_rlbk_planning$ -- This function builds the rollback steps for a rollback operation. -- It stores the result into the emaj_rlbk_plan table. -- The function returns the effective number of tables to process. -- It is called to perform a rollback operation. It is also called to simulate a rollback operation and get its duration estime. -- It is called in an autonomous dblink transaction, if possible. -- The function is defined as SECURITY DEFINER so that emaj_viewer role can write into rollback tables, when estimating the rollback -- duration, without having specific privileges on them to do it. DECLARE v_groupNames TEXT[]; v_mark TEXT; v_isLoggedRlbk BOOLEAN; v_nbSession INT; v_ctrlStepName emaj._rlbk_step_enum; v_markTimeId BIGINT; v_avg_row_rlbk INTERVAL; v_avg_row_del_log INTERVAL; v_avg_fkey_check INTERVAL; v_fixed_step_rlbk INTERVAL; v_fixed_dblink_rlbk INTERVAL; v_effNbTable INT; v_isEmajExtension BOOLEAN; v_batchNumber INT; v_checks INT; v_estimDuration INTERVAL; v_estimMethod INT; v_estimDropFkDuration INTERVAL; v_estimDropFkMethod INT; v_estimSetFkDefDuration INTERVAL; v_estimSetFkDefMethod INT; v_sessionLoad INTERVAL[]; v_minSession INT; v_minDuration INTERVAL; v_nbStep INT; r_tbl RECORD; r_fk RECORD; r_batch RECORD; BEGIN -- Get the rollback characteristics for the emaj_rlbk event. SELECT rlbk_groups, rlbk_mark, rlbk_is_logged, rlbk_nb_session, CASE WHEN rlbk_is_dblink_used THEN 'CTRL+DBLINK'::emaj._rlbk_step_enum ELSE 'CTRL-DBLINK'::emaj._rlbk_step_enum END INTO v_groupNames, v_mark, v_isLoggedRlbk, v_nbSession, v_ctrlStepName FROM emaj.emaj_rlbk WHERE rlbk_id = p_rlbkId; -- Get some mark attributes from emaj_mark. SELECT mark_time_id INTO v_markTimeId FROM emaj.emaj_mark WHERE mark_group = v_groupNames[1] AND mark_name = v_mark; -- Get all duration parameters that will be needed later from the emaj_param table, or get default values for rows -- that are not present in emaj_param table. SELECT coalesce ((SELECT param_value_interval FROM emaj.emaj_param WHERE param_key = 'avg_row_rollback_duration'),'100 microsecond'::INTERVAL), coalesce ((SELECT param_value_interval FROM emaj.emaj_param WHERE param_key = 'avg_row_delete_log_duration'),'10 microsecond'::INTERVAL), coalesce ((SELECT param_value_interval FROM emaj.emaj_param WHERE param_key = 'avg_fkey_check_duration'),'5 microsecond'::INTERVAL), coalesce ((SELECT param_value_interval FROM emaj.emaj_param WHERE param_key = 'fixed_step_rollback_duration'),'2.5 millisecond'::INTERVAL), coalesce ((SELECT param_value_interval FROM emaj.emaj_param WHERE param_key = 'fixed_dblink_rollback_duration'),'4 millisecond'::INTERVAL) INTO v_avg_row_rlbk, v_avg_row_del_log, v_avg_fkey_check, v_fixed_step_rlbk, v_fixed_dblink_rlbk; -- Insert into emaj_rlbk_plan a row per table currently belonging to the tables groups to process. INSERT INTO emaj.emaj_rlbk_plan (rlbp_rlbk_id, rlbp_step, rlbp_schema, rlbp_table, rlbp_object, rlbp_is_repl_role_replica) SELECT p_rlbkId, 'LOCK_TABLE', rel_schema, rel_tblseq, '', FALSE FROM emaj.emaj_relation WHERE upper_inf(rel_time_range) AND rel_group = ANY(v_groupNames) AND rel_kind = 'r'; -- Insert into emaj_rlbk_plan a row per table to effectively rollback. -- The numbers of log rows is computed using the _log_stat_tbl() function. -- A final check will be performed after tables will be locked to be sure no new table will have been updated. INSERT INTO emaj.emaj_rlbk_plan (rlbp_rlbk_id, rlbp_step, rlbp_schema, rlbp_table, rlbp_object, rlbp_is_repl_role_replica, rlbp_target_time_id, rlbp_estimated_quantity) SELECT p_rlbkId, 'RLBK_TABLE', rel_schema, rel_tblseq, '', FALSE, greatest(v_markTimeId, lower(rel_time_range)), emaj._log_stat_tbl(t, greatest(v_markTimeId, lower(rel_time_range)), NULL) FROM (SELECT * FROM emaj.emaj_relation WHERE upper_inf(rel_time_range) AND rel_group = ANY (v_groupNames) AND rel_kind = 'r' ) AS t WHERE emaj._log_stat_tbl(t, greatest(v_markTimeId, lower(rel_time_range)), NULL) > 0; GET DIAGNOSTICS v_effNbTable = ROW_COUNT; -- For tables having all foreign keys linking tables in the rolled back groups, set the rlbp_is_repl_role_replica flag to TRUE. -- This only concerns emaj installed as an extension because one needs to be sure that the the _rlbk_tbl() function is executed with a -- superuser role (this is needed to set the session_replication_role to 'replica'). v_isEmajExtension = EXISTS (SELECT 1 FROM pg_catalog.pg_extension WHERE extname = 'emaj'); IF v_isEmajExtension AND v_effNbTable > 0 THEN WITH fkeys AS ( -- the foreign keys belonging to tables to rollback SELECT rlbp_schema, rlbp_table, c.conname, nf.nspname, tf.relname, rel_group, rel_group = ANY (v_groupNames) AS are_both_tables_in_groups FROM emaj.emaj_rlbk_plan, pg_catalog.pg_constraint c JOIN pg_catalog.pg_class t ON (t.oid = c.conrelid) JOIN pg_catalog.pg_namespace n ON (n.oid = t.relnamespace) JOIN pg_catalog.pg_class tf ON (tf.oid = c.confrelid) JOIN pg_catalog.pg_namespace nf ON (nf.oid = tf.relnamespace) LEFT OUTER JOIN emaj.emaj_relation ON (rel_schema = nf.nspname AND rel_tblseq = tf.relname AND upper_inf(rel_time_range)) WHERE rlbp_rlbk_id = p_rlbkId -- The RLBK_TABLE steps for this rollback operation AND rlbp_step = 'RLBK_TABLE' AND contype = 'f' -- FK constraints AND tf.relkind = 'r' -- only constraints referencing true tables, ie. excluding -- partitionned tables AND t.relname = rlbp_table AND n.nspname = rlbp_schema UNION -- the foreign keys referencing tables to rollback SELECT rlbp_schema, rlbp_table, c.conname, n.nspname, t.relname, rel_group, rel_group = ANY (v_groupNames) AS are_both_tables_in_groups FROM emaj.emaj_rlbk_plan, pg_catalog.pg_constraint c JOIN pg_catalog.pg_class t ON (t.oid = c.conrelid) JOIN pg_catalog.pg_namespace n ON (n.oid = t.relnamespace) JOIN pg_catalog.pg_class tf ON (tf.oid = c.confrelid) JOIN pg_catalog.pg_namespace nf ON (nf.oid = tf.relnamespace) LEFT OUTER JOIN emaj.emaj_relation ON (rel_schema = n.nspname AND rel_tblseq = t.relname AND upper_inf(rel_time_range)) WHERE rlbp_rlbk_id = p_rlbkId -- The RLBK_TABLE steps for this rollback operation AND rlbp_step = 'RLBK_TABLE' AND contype = 'f' -- FK constraints AND t.relkind = 'r' -- only constraints referenced by true tables, ie. excluding -- partitionned tables AND tf.relname = rlbp_table AND nf.nspname = rlbp_schema ), fkeys_agg AS ( -- aggregated foreign keys by tables to rollback SELECT rlbp_schema, rlbp_table, count(*) AS nb_all_fk, count(*) FILTER (WHERE are_both_tables_in_groups) AS nb_fk_groups_ok FROM fkeys GROUP BY 1,2 ) UPDATE emaj.emaj_rlbk_plan SET rlbp_is_repl_role_replica = TRUE FROM fkeys_agg WHERE rlbp_rlbk_id = p_rlbkId -- The RLBK_TABLE steps for this rollback operation AND rlbp_step IN ('RLBK_TABLE', 'LOCK_TABLE') AND emaj_rlbk_plan.rlbp_table = fkeys_agg.rlbp_table AND emaj_rlbk_plan.rlbp_schema = fkeys_agg.rlbp_schema AND nb_all_fk = nb_fk_groups_ok -- if all fkeys are linking tables in the rolled back groups ; END IF; -- -- Group tables into batchs to process all tables linked by foreign keys as a batch. -- v_batchNumber = 1; -- Allocate tables with rows to rollback to batch number starting with the heaviest to rollback tables as reported by the -- emaj_log_stat_group() function. FOR r_tbl IN SELECT rlbp_schema, rlbp_table, rlbp_is_repl_role_replica FROM emaj.emaj_rlbk_plan WHERE rlbp_rlbk_id = p_rlbkId AND rlbp_step = 'RLBK_TABLE' ORDER BY rlbp_estimated_quantity DESC, rlbp_schema, rlbp_table LOOP -- If the table is not already allocated to a batch number (it may have been already allocated because of a fkey link). IF EXISTS (SELECT 0 FROM emaj.emaj_rlbk_plan WHERE rlbp_rlbk_id = p_rlbkId AND rlbp_step = 'RLBK_TABLE' AND rlbp_schema = r_tbl.rlbp_schema AND rlbp_table = r_tbl.rlbp_table AND rlbp_batch_number IS NULL ) THEN -- Allocate the table to the batch number, with all other tables linked by foreign key constraints. PERFORM emaj._rlbk_set_batch_number(p_rlbkId, v_batchNumber, r_tbl.rlbp_schema, r_tbl.rlbp_table, r_tbl.rlbp_is_repl_role_replica); v_batchNumber = v_batchNumber + 1; END IF; END LOOP; -- -- If unlogged rollback, register into emaj_rlbk_plan "disable log triggers", "deletes from log tables" -- and "enable log trigger" steps. -- IF NOT v_isLoggedRlbk THEN -- Compute the cost for each DIS_LOG_TRG step. SELECT p_estimateMethod, p_estimatedDuration INTO v_estimMethod, v_estimDuration FROM emaj._estimate_rlbk_step_duration('DIS_LOG_TRG', NULL, NULL, NULL, NULL, v_fixed_step_rlbk, NULL); -- Insert all DIS_LOG_TRG steps. INSERT INTO emaj.emaj_rlbk_plan (rlbp_rlbk_id, rlbp_step, rlbp_schema, rlbp_table, rlbp_object, rlbp_batch_number, rlbp_estimated_duration, rlbp_estimate_method) SELECT p_rlbkId, 'DIS_LOG_TRG', rlbp_schema, rlbp_table, '', rlbp_batch_number, v_estimDuration, v_estimMethod FROM emaj.emaj_rlbk_plan WHERE rlbp_rlbk_id = p_rlbkId AND rlbp_step = 'RLBK_TABLE'; -- Insert all DELETE_LOG steps. But the duration estimates will be computed later. -- The estimated number of log rows to delete is set to the estimated number of updates. This is underestimated in particular when -- SQL UPDATES are logged. But the collected statistics used for duration estimates are also based on the estimated number of updates. INSERT INTO emaj.emaj_rlbk_plan (rlbp_rlbk_id, rlbp_step, rlbp_schema, rlbp_table, rlbp_object, rlbp_target_time_id, rlbp_batch_number, rlbp_estimated_quantity) SELECT p_rlbkId, 'DELETE_LOG', rlbp_schema, rlbp_table, '', rlbp_target_time_id, rlbp_batch_number, rlbp_estimated_quantity FROM emaj.emaj_rlbk_plan WHERE rlbp_rlbk_id = p_rlbkId AND rlbp_step = 'RLBK_TABLE'; -- Compute the cost for each ENA_LOG_TRG step. SELECT p_estimateMethod, p_estimatedDuration INTO v_estimMethod, v_estimDuration FROM emaj._estimate_rlbk_step_duration('ENA_LOG_TRG', NULL, NULL, NULL, NULL, v_fixed_step_rlbk, NULL); -- Insert all ENA_LOG_TRG steps. INSERT INTO emaj.emaj_rlbk_plan (rlbp_rlbk_id, rlbp_step, rlbp_schema, rlbp_table, rlbp_object, rlbp_batch_number, rlbp_estimated_duration, rlbp_estimate_method) SELECT p_rlbkId, 'ENA_LOG_TRG', rlbp_schema, rlbp_table, '', rlbp_batch_number, v_estimDuration, v_estimMethod FROM emaj.emaj_rlbk_plan WHERE rlbp_rlbk_id = p_rlbkId AND rlbp_step = 'RLBK_TABLE'; END IF; -- -- Process application triggers to temporarily set as ALWAYS triggers. -- This concerns triggers that must be kept enabled during the rollback processing but the rollback function for its table is executed -- with session_replication_role = replica. -- -- Compute the cost for each SET_ALWAYS_APP_TRG step. SELECT p_estimateMethod, p_estimatedDuration INTO v_estimMethod, v_estimDuration FROM emaj._estimate_rlbk_step_duration('SET_ALWAYS_APP_TRG', NULL, NULL, NULL, NULL, v_fixed_step_rlbk, NULL); -- Insert all SET_ALWAYS_APP_TRG steps. INSERT INTO emaj.emaj_rlbk_plan (rlbp_rlbk_id, rlbp_step, rlbp_schema, rlbp_table, rlbp_object, rlbp_batch_number, rlbp_estimated_duration, rlbp_estimate_method) SELECT p_rlbkId, 'SET_ALWAYS_APP_TRG', rlbp_schema, rlbp_table, tgname, rlbp_batch_number, v_estimDuration, v_estimMethod FROM emaj.emaj_rlbk_plan JOIN pg_catalog.pg_class ON (relname = rlbp_table) JOIN pg_catalog.pg_namespace ON (pg_namespace.oid = relnamespace AND nspname = rlbp_schema) JOIN pg_catalog.pg_trigger ON (tgrelid = pg_class.oid) WHERE rlbp_rlbk_id = p_rlbkId AND rlbp_step = 'RLBK_TABLE' -- rollback step AND rlbp_is_repl_role_replica -- ... in session_replication_role = replica AND NOT tgisinternal -- application triggers only AND tgname NOT IN ('emaj_trunc_trg','emaj_log_trg') AND tgenabled = 'O' -- ... enabled in local mode AND EXISTS -- ... and to be kept enabled (SELECT 0 FROM emaj.emaj_relation WHERE rel_schema = rlbp_schema AND rel_tblseq = rlbp_table AND upper_inf(rel_time_range) AND tgname = ANY (rel_ignored_triggers) ); -- Compute the cost for each SET_LOCAL_APP_TRG step. SELECT p_estimateMethod, p_estimatedDuration INTO v_estimMethod, v_estimDuration FROM emaj._estimate_rlbk_step_duration('SET_LOCAL_APP_TRG', NULL, NULL, NULL, NULL, v_fixed_step_rlbk, NULL); -- Insert all SET_LOCAL_APP_TRG steps INSERT INTO emaj.emaj_rlbk_plan (rlbp_rlbk_id, rlbp_step, rlbp_schema, rlbp_table, rlbp_object, rlbp_batch_number, rlbp_estimated_duration, rlbp_estimate_method) SELECT p_rlbkId, 'SET_LOCAL_APP_TRG', rlbp_schema, rlbp_table, rlbp_object, rlbp_batch_number, v_estimDuration, v_estimMethod FROM emaj.emaj_rlbk_plan WHERE rlbp_rlbk_id = p_rlbkId AND rlbp_step = 'SET_ALWAYS_APP_TRG'; -- -- Process application triggers to disable and re-enable. -- This concerns triggers that must be disabled during the rollback processing and the rollback function for its table is not executed -- with session_replication_role = replica. -- -- Compute the cost for each DIS_APP_TRG step. SELECT p_estimateMethod, p_estimatedDuration INTO v_estimMethod, v_estimDuration FROM emaj._estimate_rlbk_step_duration('DIS_APP_TRG', NULL, NULL, NULL, NULL, v_fixed_step_rlbk, NULL); -- Insert all DIS_APP_TRG steps. INSERT INTO emaj.emaj_rlbk_plan (rlbp_rlbk_id, rlbp_step, rlbp_schema, rlbp_table, rlbp_object, rlbp_batch_number, rlbp_estimated_duration, rlbp_estimate_method) SELECT p_rlbkId, 'DIS_APP_TRG', rlbp_schema, rlbp_table, tgname, rlbp_batch_number, v_estimDuration, v_estimMethod FROM emaj.emaj_rlbk_plan JOIN pg_catalog.pg_class ON (relname = rlbp_table) JOIN pg_catalog.pg_namespace ON (pg_namespace.oid = relnamespace AND nspname = rlbp_schema) JOIN pg_catalog.pg_trigger ON (tgrelid = pg_class.oid) WHERE rlbp_rlbk_id = p_rlbkId AND rlbp_step = 'RLBK_TABLE' -- rollback step AND NOT tgisinternal -- application triggers only AND tgname NOT IN ('emaj_trunc_trg','emaj_log_trg') AND (tgenabled IN ('A', 'R') -- enabled ALWAYS or REPLICA triggers OR (tgenabled = 'O' AND NOT rlbp_is_repl_role_replica) -- or enabled ORIGIN triggers for rollbacks not processed ) -- in session_replication_role = replica) AND NOT EXISTS -- ... that must be disabled (SELECT 0 FROM emaj.emaj_relation WHERE rel_schema = rlbp_schema AND rel_tblseq = rlbp_table AND upper_inf(rel_time_range) AND tgname = ANY (rel_ignored_triggers) ); -- Compute the cost for each ENA_APP_TRG step. SELECT p_estimateMethod, p_estimatedDuration INTO v_estimMethod, v_estimDuration FROM emaj._estimate_rlbk_step_duration('ENA_APP_TRG', NULL, NULL, NULL, NULL, v_fixed_step_rlbk, NULL); -- Insert all ENA_APP_TRG steps. INSERT INTO emaj.emaj_rlbk_plan (rlbp_rlbk_id, rlbp_step, rlbp_schema, rlbp_table, rlbp_object, rlbp_app_trg_type, rlbp_batch_number, rlbp_estimated_duration, rlbp_estimate_method) SELECT p_rlbkId, 'ENA_APP_TRG', rlbp_schema, rlbp_table, rlbp_object, CASE tgenabled WHEN 'A' THEN 'ALWAYS' WHEN 'R' THEN 'REPLICA' ELSE '' END, rlbp_batch_number, v_estimDuration, v_estimMethod FROM emaj.emaj_rlbk_plan JOIN pg_catalog.pg_class ON (relname = rlbp_table) JOIN pg_catalog.pg_namespace ON (pg_namespace.oid = relnamespace AND nspname = rlbp_schema) JOIN pg_catalog.pg_trigger ON (tgrelid = pg_class.oid AND tgname = rlbp_object) WHERE rlbp_rlbk_id = p_rlbkId AND rlbp_step = 'DIS_APP_TRG'; -- -- Process foreign key to define which action to perform on them -- -- First compute the fixed duration estimates for each 'DROP_FK' and 'SET_FK_DEF' steps. SELECT p_estimateMethod, p_estimatedDuration INTO v_estimDropFkMethod, v_estimDropFkDuration FROM emaj._estimate_rlbk_step_duration('DROP_FK', NULL, NULL, NULL, NULL, v_fixed_step_rlbk, NULL); SELECT p_estimateMethod, p_estimatedDuration INTO v_estimSetFkDefMethod, v_estimSetFkDefDuration FROM emaj._estimate_rlbk_step_duration('SET_FK_DEF', NULL, NULL, NULL, NULL, v_fixed_step_rlbk, NULL); -- Select all foreign keys belonging to or referencing the tables to process. FOR r_fk IN SELECT c.oid AS conoid, c.conname, n.nspname, t.relname, t.reltuples, pg_get_constraintdef(c.oid) AS def, c.condeferrable, c.condeferred, c.confupdtype, c.confdeltype, r.rlbp_batch_number FROM emaj.emaj_rlbk_plan r JOIN pg_catalog.pg_class t ON (t.relname = r.rlbp_table) JOIN pg_catalog.pg_namespace n ON (t.relnamespace = n.oid AND n.nspname = r.rlbp_schema) JOIN pg_catalog.pg_constraint c ON (c.conrelid = t.oid) WHERE c.contype = 'f' -- FK constraints only AND rlbp_rlbk_id = p_rlbkId AND rlbp_step = 'RLBK_TABLE' -- Tables to rollback AND NOT rlbp_is_repl_role_replica -- ... not in a session_replication_role = replica UNION SELECT c.oid AS conoid, c.conname, n.nspname, t.relname, t.reltuples, pg_get_constraintdef(c.oid) AS def, c.condeferrable, c.condeferred, c.confupdtype, c.confdeltype, r.rlbp_batch_number FROM emaj.emaj_rlbk_plan r JOIN pg_catalog.pg_class rt ON (rt.relname = r.rlbp_table) JOIN pg_catalog.pg_namespace rn ON (rn.oid = rt.relnamespace AND rn.nspname = r.rlbp_schema) JOIN pg_catalog.pg_constraint c ON (c.confrelid = rt.oid) JOIN pg_catalog.pg_class t ON (t.oid = c.conrelid) JOIN pg_catalog.pg_namespace n ON (n.oid = t.relnamespace) WHERE c.contype = 'f' -- FK constraints only AND rlbp_rlbk_id = p_rlbkId AND rlbp_step = 'RLBK_TABLE' -- Tables to rollback AND NOT rlbp_is_repl_role_replica -- ... not in a session_replication_role = replica ORDER BY nspname, relname, conname LOOP -- Depending on the foreign key characteristics, record as 'to be dropped' or 'to be set deferred' or 'to just be reset immediate'. IF NOT r_fk.condeferrable OR r_fk.confupdtype <> 'a' OR r_fk.confdeltype <> 'a' THEN -- Non deferrable fkeys and deferrable fkeys with an action for UPDATE or DELETE other than 'no action' need to be dropped. INSERT INTO emaj.emaj_rlbk_plan ( rlbp_rlbk_id, rlbp_step, rlbp_schema, rlbp_table, rlbp_object, rlbp_batch_number, rlbp_estimated_duration, rlbp_estimate_method ) VALUES ( p_rlbkId, 'DROP_FK', r_fk.nspname, r_fk.relname, r_fk.conname, r_fk.rlbp_batch_number, v_estimDropFkDuration, v_estimDropFkMethod ); INSERT INTO emaj.emaj_rlbk_plan ( rlbp_rlbk_id, rlbp_step, rlbp_schema, rlbp_table, rlbp_object, rlbp_batch_number, rlbp_object_def, rlbp_estimated_quantity ) VALUES ( p_rlbkId, 'ADD_FK', r_fk.nspname, r_fk.relname, r_fk.conname, r_fk.rlbp_batch_number, r_fk.def, r_fk.reltuples ); ELSE -- Other deferrable but not deferred fkeys need to be set deferred. IF NOT r_fk.condeferred THEN INSERT INTO emaj.emaj_rlbk_plan ( rlbp_rlbk_id, rlbp_step, rlbp_schema, rlbp_table, rlbp_object, rlbp_batch_number, rlbp_estimated_duration, rlbp_estimate_method ) VALUES ( p_rlbkId, 'SET_FK_DEF', r_fk.nspname, r_fk.relname, r_fk.conname, r_fk.rlbp_batch_number, v_estimSetFkDefDuration, v_estimSetFkDefMethod ); END IF; -- Deferrable fkeys are recorded as 'to be set immediate at the end of the rollback operation'. -- Compute the number of fkey values to check at set immediate time. SELECT (coalesce( -- Get the number of rolled back rows in the referencing table, if any. (SELECT rlbp_estimated_quantity FROM emaj.emaj_rlbk_plan WHERE rlbp_rlbk_id = p_rlbkId AND rlbp_step = 'RLBK_TABLE' -- tables of the rollback event AND rlbp_schema = r_fk.nspname AND rlbp_table = r_fk.relname) -- referencing schema.table , 0)) + (coalesce( -- Get the number of rolled back rows in the referenced table, if any. (SELECT rlbp_estimated_quantity FROM emaj.emaj_rlbk_plan JOIN pg_catalog.pg_class rt ON (rt.relname = rlbp_table) JOIN pg_catalog.pg_namespace rn ON (rn.oid = rt.relnamespace AND rn.nspname = rlbp_schema) JOIN pg_catalog.pg_constraint c ON (c.confrelid = rt.oid) WHERE rlbp_rlbk_id = p_rlbkId AND rlbp_step = 'RLBK_TABLE' -- tables of the rollback event AND c.oid = r_fk.conoid -- constraint id ) , 0)) INTO v_checks; -- And record the SET_FK_IMM step. INSERT INTO emaj.emaj_rlbk_plan ( rlbp_rlbk_id, rlbp_step, rlbp_schema, rlbp_table, rlbp_object, rlbp_batch_number, rlbp_estimated_quantity ) VALUES ( p_rlbkId, 'SET_FK_IMM', r_fk.nspname, r_fk.relname, r_fk.conname, r_fk.rlbp_batch_number, v_checks ); END IF; END LOOP; -- -- Now compute the estimation duration for each complex step ('RLBK_TABLE', 'DELETE_LOG', 'ADD_FK', 'SET_FK_IMM'). -- -- Compute the rollback duration estimates for the tables. FOR r_tbl IN SELECT * FROM emaj.emaj_rlbk_plan WHERE rlbp_rlbk_id = p_rlbkId AND rlbp_step = 'RLBK_TABLE' LOOP SELECT p_estimateMethod, p_estimatedDuration INTO v_estimMethod, v_estimDuration FROM emaj._estimate_rlbk_step_duration('RLBK_TABLE', r_tbl.rlbp_schema, r_tbl.rlbp_table, NULL, r_tbl.rlbp_estimated_quantity, v_fixed_step_rlbk, v_avg_row_rlbk); UPDATE emaj.emaj_rlbk_plan SET rlbp_estimated_duration = v_estimDuration, rlbp_estimate_method = v_estimMethod WHERE rlbp_rlbk_id = p_rlbkId AND rlbp_step = 'RLBK_TABLE' AND rlbp_schema = r_tbl.rlbp_schema AND rlbp_table = r_tbl.rlbp_table; END LOOP; -- Compute the estimated log rows delete duration. FOR r_tbl IN SELECT * FROM emaj.emaj_rlbk_plan WHERE rlbp_rlbk_id = p_rlbkId AND rlbp_step = 'DELETE_LOG' LOOP SELECT p_estimateMethod, p_estimatedDuration INTO v_estimMethod, v_estimDuration FROM emaj._estimate_rlbk_step_duration('DELETE_LOG', r_tbl.rlbp_schema, r_tbl.rlbp_table, NULL, r_tbl.rlbp_estimated_quantity, v_fixed_step_rlbk, v_avg_row_del_log); UPDATE emaj.emaj_rlbk_plan SET rlbp_estimated_duration = v_estimDuration, rlbp_estimate_method = v_estimMethod WHERE rlbp_rlbk_id = p_rlbkId AND rlbp_step = 'DELETE_LOG' AND rlbp_schema = r_tbl.rlbp_schema AND rlbp_table = r_tbl.rlbp_table; END LOOP; -- Compute the fkey recreation duration. FOR r_fk IN SELECT * FROM emaj.emaj_rlbk_plan WHERE rlbp_rlbk_id = p_rlbkId AND rlbp_step = 'ADD_FK' LOOP SELECT p_estimateMethod, p_estimatedDuration INTO v_estimMethod, v_estimDuration FROM emaj._estimate_rlbk_step_duration('ADD_FK', r_tbl.rlbp_schema, r_tbl.rlbp_table, r_fk.rlbp_object, r_tbl.rlbp_estimated_quantity, v_fixed_step_rlbk, v_avg_fkey_check); UPDATE emaj.emaj_rlbk_plan SET rlbp_estimated_duration = v_estimDuration, rlbp_estimate_method = v_estimMethod WHERE rlbp_rlbk_id = p_rlbkId AND rlbp_step = 'ADD_FK' AND rlbp_schema = r_fk.rlbp_schema AND rlbp_table = r_fk.rlbp_table AND rlbp_object = r_fk.rlbp_object; END LOOP; -- Compute the fkey checks duration. FOR r_fk IN SELECT * FROM emaj.emaj_rlbk_plan WHERE rlbp_rlbk_id = p_rlbkId AND rlbp_step = 'SET_FK_IMM' LOOP SELECT p_estimateMethod, p_estimatedDuration INTO v_estimMethod, v_estimDuration FROM emaj._estimate_rlbk_step_duration('SET_FK_IMM', r_tbl.rlbp_schema, r_tbl.rlbp_table, r_fk.rlbp_object, r_tbl.rlbp_estimated_quantity, v_fixed_step_rlbk, v_avg_fkey_check); UPDATE emaj.emaj_rlbk_plan SET rlbp_estimated_duration = v_estimDuration, rlbp_estimate_method = v_estimMethod WHERE rlbp_rlbk_id = p_rlbkId AND rlbp_step = 'SET_FK_IMM' AND rlbp_schema = r_fk.rlbp_schema AND rlbp_table = r_fk.rlbp_table AND rlbp_object = r_fk.rlbp_object; END LOOP; -- -- Allocate batch number to sessions to spread the load on sessions as best as possible. -- A batch represents all steps related to the processing of one table or several tables linked by foreign keys. -- -- Initialisation. FOR v_session IN 1 .. v_nbSession LOOP v_sessionLoad [v_session] = '0 SECONDS'::INTERVAL; END LOOP; -- Allocate tables batch to sessions, starting with the heaviest to rollback batch. FOR r_batch IN SELECT rlbp_batch_number, sum(rlbp_estimated_duration) AS batch_duration FROM emaj.emaj_rlbk_plan WHERE rlbp_rlbk_id = p_rlbkId AND rlbp_batch_number IS NOT NULL GROUP BY rlbp_batch_number ORDER BY sum(rlbp_estimated_duration) DESC LOOP -- Compute the least loaded session. v_minSession=1; v_minDuration = v_sessionLoad [1]; FOR v_session IN 2 .. v_nbSession LOOP IF v_sessionLoad [v_session] < v_minDuration THEN v_minSession = v_session; v_minDuration = v_sessionLoad [v_session]; END IF; END LOOP; -- Allocate the batch to the session. UPDATE emaj.emaj_rlbk_plan SET rlbp_session = v_minSession WHERE rlbp_rlbk_id = p_rlbkId AND rlbp_batch_number = r_batch.rlbp_batch_number; v_sessionLoad [v_minSession] = v_sessionLoad [v_minSession] + r_batch.batch_duration; END LOOP; -- Assign session 1 to all 'LOCK_TABLE' steps not yet affected. UPDATE emaj.emaj_rlbk_plan SET rlbp_session = 1 WHERE rlbp_rlbk_id = p_rlbkId AND rlbp_session IS NULL; -- Create the pseudo 'CTRL+DBLINK' or 'CTRL-DBLINK' step and compute its duration estimate. -- Get the number of recorded steps (except LOCK_TABLE). SELECT count(*) INTO v_nbStep FROM emaj.emaj_rlbk_plan WHERE rlbp_rlbk_id = p_rlbkId AND rlbp_step <> 'LOCK_TABLE'; IF v_nbStep > 0 THEN -- If CTRLxDBLINK statistics are available, compute an average cost. SELECT sum(rlbt_duration) * v_nbStep / sum(rlbt_quantity) INTO v_estimDuration FROM emaj.emaj_rlbk_stat WHERE rlbt_step = v_ctrlStepName AND rlbt_quantity > 0; v_estimMethod = 2; IF v_estimDuration IS NULL THEN -- Otherwise, use the fixed_step_rollback_duration parameter. v_estimDuration = v_fixed_dblink_rlbk * v_nbStep; v_estimMethod = 3; END IF; -- Insert the 'CTRLxDBLINK' pseudo step. INSERT INTO emaj.emaj_rlbk_plan ( rlbp_rlbk_id, rlbp_step, rlbp_schema, rlbp_table, rlbp_object, rlbp_estimated_quantity, rlbp_estimated_duration, rlbp_estimate_method ) VALUES ( p_rlbkId, v_ctrlStepName, '', '', '', v_nbStep, v_estimDuration, v_estimMethod ); END IF; -- Return the number of tables to effectively rollback. RETURN v_effNbTable; END; $_rlbk_planning$; CREATE OR REPLACE FUNCTION emaj._rlbk_session_lock(p_rlbkId INT, p_session INT) RETURNS VOID LANGUAGE plpgsql AS $_rlbk_session_lock$ -- It opens the session if needed, creates the session row in the emaj_rlbk_session table -- and then locks all the application tables for the session. DECLARE v_isDblinkUsed BOOLEAN; v_dblinkSchema TEXT; v_dbLinkCnxStatus INT; v_stmt TEXT; v_groupNames TEXT[]; v_nbRetry SMALLINT = 0; v_ok BOOLEAN = FALSE; v_nbTbl INT; r_tbl RECORD; BEGIN -- Get the rollback characteristics from the emaj_rlbk table. SELECT rlbk_is_dblink_used, rlbk_dblink_schema, rlbk_groups INTO v_isDblinkUsed, v_dblinkSchema, v_groupNames FROM emaj.emaj_rlbk WHERE rlbk_id = p_rlbkId; -- For dblink session > 1, open the connection (the session 1 is already opened). IF p_session > 1 THEN SELECT p_status INTO v_dbLinkCnxStatus FROM emaj._dblink_open_cnx('rlbk#' || p_session); IF v_dbLinkCnxStatus < 0 THEN RAISE EXCEPTION '_rlbk_session_lock: Error while opening the dblink session #% (Status of the dblink connection attempt = %' ' - see E-Maj documentation).', p_session, v_dbLinkCnxStatus; END IF; -- ... and create the session row the emaj_rlbk_session table. v_stmt = 'INSERT INTO emaj.emaj_rlbk_session (rlbs_rlbk_id, rlbs_session, rlbs_txid, rlbs_start_datetime) ' || 'VALUES (' || p_rlbkId || ',' || p_session || ',' || txid_current() || ',' || quote_literal(clock_timestamp()) || ') RETURNING 1'; PERFORM emaj._dblink_sql_exec('rlbk#' || p_session, v_stmt, v_dblinkSchema); END IF; -- Insert a BEGIN event into the history. INSERT INTO emaj.emaj_hist (hist_function, hist_event, hist_object, hist_wording) VALUES ('LOCK_GROUP', 'BEGIN', array_to_string(v_groupNames,','), 'Rollback session #' || p_session); -- -- Acquire locks on tables. -- -- In case of deadlock, retry up to 5 times. WHILE NOT v_ok AND v_nbRetry < 5 LOOP BEGIN v_nbTbl = 0; -- Scan all tables of the session, in priority ascending order. FOR r_tbl IN SELECT quote_ident(rlbp_schema) || '.' || quote_ident(rlbp_table) AS fullName, EXISTS (SELECT 1 FROM emaj.emaj_rlbk_plan rlbp2 WHERE rlbp2.rlbp_rlbk_id = p_rlbkId AND rlbp2.rlbp_session = p_session AND rlbp2.rlbp_schema = rlbp1.rlbp_schema AND rlbp2.rlbp_table = rlbp1.rlbp_table AND rlbp2.rlbp_step = 'DIS_LOG_TRG' ) AS disLogTrg FROM emaj.emaj_rlbk_plan rlbp1 JOIN emaj.emaj_relation ON (rel_schema = rlbp_schema AND rel_tblseq = rlbp_table AND upper_inf(rel_time_range)) WHERE rlbp_rlbk_id = p_rlbkId AND rlbp_step = 'LOCK_TABLE' AND rlbp_session = p_session ORDER BY rel_priority, rel_schema, rel_tblseq LOOP -- Lock each table. -- The locking level is EXCLUSIVE mode. -- This blocks all concurrent update capabilities of all tables of the groups (including tables with no logged update to rollback), -- in order to ensure a stable state of the group at the end of the rollback operation). -- But these tables can be accessed by SELECT statements during the E-Maj rollback. EXECUTE format('LOCK TABLE %s IN EXCLUSIVE MODE', r_tbl.fullName); v_nbTbl = v_nbTbl + 1; END LOOP; -- OK, all tables locked. v_ok = TRUE; EXCEPTION WHEN deadlock_detected THEN v_nbRetry = v_nbRetry + 1; RAISE NOTICE '_rlbk_session_lock: A deadlock has been trapped while locking tables for groups "%".', array_to_string(v_groupNames,','); END; END LOOP; IF NOT v_ok THEN PERFORM emaj._rlbk_error(p_rlbkId, '_rlbk_session_lock: Too many (5) deadlocks encountered while locking tables', 'rlbk#' || p_session); RAISE EXCEPTION '_rlbk_session_lock: Too many (5) deadlocks encountered while locking tables for groups "%".', array_to_string(v_groupNames,','); END IF; -- Insert a END event into the history. INSERT INTO emaj.emaj_hist (hist_function, hist_event, hist_object, hist_wording) VALUES ('LOCK_GROUP', 'END', array_to_string(v_groupNames,','), 'Rollback session #' || p_session || ': ' || v_nbTbl || ' tables locked, ' || v_nbRetry || ' deadlock(s)'); -- RETURN; -- Trap and record exception during the rollback operation. EXCEPTION WHEN SQLSTATE 'P0001' THEN -- Do not trap the exceptions raised by the function RAISE; WHEN OTHERS THEN -- Otherwise, log the E-Maj rollback abort in emaj_rlbk, if possible PERFORM emaj._rlbk_error(p_rlbkId, 'In _rlbk_session_lock() for session ' || p_session || ': ' || SQLERRM, 'rlbk#' || p_session); RAISE; END; $_rlbk_session_lock$; CREATE OR REPLACE FUNCTION emaj._rlbk_session_exec(p_rlbkId INT, p_session INT) RETURNS VOID LANGUAGE plpgsql AS $_rlbk_session_exec$ -- This function executes the main part of a rollback operation. -- It executes the steps identified by _rlbk_planning() and stored into emaj_rlbk_plan, for one session. -- It updates the emaj_rlbk_plan table, using dblink connection if possible, giving a visibility of the rollback progress. DECLARE v_stmt TEXT; v_dblinkSchema TEXT; v_isDblinkUsed BOOLEAN; v_groupNames TEXT[]; v_mark TEXT; v_rlbkMarkTimeId BIGINT; v_rlbkTimeId BIGINT; v_isLoggedRlbk BOOLEAN; v_nbSession INT; v_maxGlobalSeq BIGINT; v_lastGlobalSeq BIGINT; v_fullTableName TEXT; v_nbRows BIGINT; r_step RECORD; BEGIN -- Get the rollback characteristics from the emaj_rlbk table. SELECT rlbk_groups, rlbk_mark, rlbk_time_id, rlbk_is_logged, rlbk_nb_session, rlbk_dblink_schema, rlbk_is_dblink_used, time_last_emaj_gid INTO v_groupNames, v_mark, v_rlbkTimeId, v_isLoggedRlbk, v_nbSession, v_dblinkSchema, v_isDblinkUsed, v_maxGlobalSeq FROM emaj.emaj_rlbk JOIN emaj.emaj_time_stamp ON (time_id = rlbk_time_id) WHERE rlbk_id = p_rlbkId; -- Fetch the mark_time_id, the last global sequence at set_mark time for the first group of the groups array. -- They all share the same values. SELECT mark_time_id, time_last_emaj_gid INTO v_rlbkMarkTimeId, v_lastGlobalSeq FROM emaj.emaj_mark JOIN emaj.emaj_time_stamp ON (time_id = mark_time_id) WHERE mark_group = v_groupNames[1] AND mark_name = v_mark; -- Scan emaj_rlbp_plan to get all steps to process that have been affected to this session, in batch_number and step order. FOR r_step IN SELECT rlbp_step, rlbp_schema, rlbp_table, rlbp_object, rlbp_object_def, rlbp_app_trg_type, rlbp_is_repl_role_replica, rlbp_target_time_id FROM emaj.emaj_rlbk_plan WHERE rlbp_rlbk_id = p_rlbkId AND rlbp_step NOT IN ('LOCK_TABLE','CTRL-DBLINK','CTRL+DBLINK') AND rlbp_session = p_session ORDER BY rlbp_batch_number, rlbp_step, rlbp_table, rlbp_object LOOP -- Update the emaj_rlbk_plan table to set the step start time. v_stmt = 'UPDATE emaj.emaj_rlbk_plan SET rlbp_start_datetime = clock_timestamp() ' || ' WHERE rlbp_rlbk_id = ' || p_rlbkId || ' AND rlbp_step = ' || quote_literal(r_step.rlbp_step) || ' AND rlbp_schema = ' || quote_literal(r_step.rlbp_schema) || ' AND rlbp_table = ' || quote_literal(r_step.rlbp_table) || ' AND rlbp_object = ' || quote_literal(r_step.rlbp_object) || ' RETURNING 1'; PERFORM emaj._dblink_sql_exec('rlbk#' || p_session, v_stmt, v_dblinkSchema); v_fullTableName = quote_ident(r_step.rlbp_schema) || '.' || quote_ident(r_step.rlbp_table); -- Process the step depending on its type. CASE r_step.rlbp_step WHEN 'DIS_APP_TRG' THEN -- Disable an application trigger. PERFORM emaj._handle_trigger_fk_tbl('DISABLE_TRIGGER', v_fullTableName, r_step.rlbp_object); WHEN 'SET_ALWAYS_APP_TRG' THEN -- Set an application trigger as an ALWAYS trigger. PERFORM emaj._handle_trigger_fk_tbl('SET_TRIGGER', v_fullTableName, r_step.rlbp_object, 'ALWAYS'); WHEN 'DIS_LOG_TRG' THEN -- Disable a log trigger. PERFORM emaj._handle_trigger_fk_tbl('DISABLE_TRIGGER', v_fullTableName, 'emaj_log_trg'); WHEN 'DROP_FK' THEN -- Delete a foreign key. PERFORM emaj._handle_trigger_fk_tbl('DROP_FK', v_fullTableName, r_step.rlbp_object); WHEN 'SET_FK_DEF' THEN -- Set a foreign key deferred. EXECUTE format('SET CONSTRAINTS %I.%I DEFERRED', r_step.rlbp_schema, r_step.rlbp_object); WHEN 'RLBK_TABLE' THEN -- Process a table rollback. -- For tables added to the group after the rollback target mark, get the last sequence value specific to each table. SELECT emaj._rlbk_tbl(emaj_relation.*, CASE WHEN v_rlbkMarkTimeId = r_step.rlbp_target_time_id THEN v_lastGlobalSeq -- common case ELSE (SELECT time_last_emaj_gid FROM emaj.emaj_time_stamp WHERE time_id = r_step.rlbp_target_time_id) END, v_maxGlobalSeq, v_nbSession, v_isLoggedRlbk, r_step.rlbp_is_repl_role_replica) INTO v_nbRows FROM emaj.emaj_relation WHERE rel_schema = r_step.rlbp_schema AND rel_tblseq = r_step.rlbp_table AND upper_inf(rel_time_range); WHEN 'DELETE_LOG' THEN -- Process the deletion of log rows. -- For tables added to the group after the rollback target mark, get the last sequence value specific to each table. SELECT emaj._delete_log_tbl(emaj_relation.*, r_step.rlbp_target_time_id, v_rlbkTimeId, CASE WHEN v_rlbkMarkTimeId = r_step.rlbp_target_time_id THEN v_lastGlobalSeq -- common case ELSE (SELECT time_last_emaj_gid FROM emaj.emaj_time_stamp WHERE time_id = r_step.rlbp_target_time_id) END) INTO v_nbRows FROM emaj.emaj_relation WHERE rel_schema = r_step.rlbp_schema AND rel_tblseq = r_step.rlbp_table AND upper_inf(rel_time_range); WHEN 'SET_FK_IMM' THEN -- Set a foreign key immediate. EXECUTE format('SET CONSTRAINTS %I.%I IMMEDIATE', r_step.rlbp_schema, r_step.rlbp_object); WHEN 'ADD_FK' THEN -- Re-create a foreign key. PERFORM emaj._handle_trigger_fk_tbl('ADD_FK', v_fullTableName, r_step.rlbp_object, r_step.rlbp_object_def); WHEN 'ENA_APP_TRG' THEN -- Enable an application trigger. PERFORM emaj._handle_trigger_fk_tbl('ENABLE_TRIGGER', v_fullTableName, r_step.rlbp_object, r_step.rlbp_app_trg_type); WHEN 'SET_LOCAL_APP_TRG' THEN -- Reset an application trigger to its common type. PERFORM emaj._handle_trigger_fk_tbl('SET_TRIGGER', v_fullTableName, r_step.rlbp_object, ''); WHEN 'ENA_LOG_TRG' THEN -- Enable a log trigger. PERFORM emaj._handle_trigger_fk_tbl('ENABLE_TRIGGER', v_fullTableName, 'emaj_log_trg', 'ALWAYS'); END CASE; -- Update the emaj_rlbk_plan table to set the step duration. -- The computed duration does not include the time needed to update the emaj_rlbk_plan table, v_stmt = 'UPDATE emaj.emaj_rlbk_plan SET rlbp_duration = ' || quote_literal(clock_timestamp()) || ' - rlbp_start_datetime'; IF r_step.rlbp_step = 'RLBK_TABLE' OR r_step.rlbp_step = 'DELETE_LOG' THEN -- ... nor the effective number of processed rows for RLBK_TABLE and DELETE_LOG steps. v_stmt = v_stmt || ' , rlbp_quantity = ' || v_nbRows; END IF; v_stmt = v_stmt || ' WHERE rlbp_rlbk_id = ' || p_rlbkId || ' AND rlbp_step = ' || quote_literal(r_step.rlbp_step) || ' AND rlbp_schema = ' || quote_literal(r_step.rlbp_schema) || ' AND rlbp_table = ' || quote_literal(r_step.rlbp_table) || ' AND rlbp_object = ' || quote_literal(r_step.rlbp_object) || ' RETURNING 1'; PERFORM emaj._dblink_sql_exec('rlbk#' || p_session, v_stmt, v_dblinkSchema); END LOOP; -- Update the emaj_rlbk_session table to set the timestamp representing the end of work for the session. v_stmt = 'UPDATE emaj.emaj_rlbk_session SET rlbs_end_datetime = clock_timestamp()' || ' WHERE rlbs_rlbk_id = ' || p_rlbkId || ' AND rlbs_session = ' || p_session || ' RETURNING 1'; PERFORM emaj._dblink_sql_exec('rlbk#' || p_session, v_stmt, v_dblinkSchema); -- Close the dblink connection, if any, for session > 1. IF v_isDblinkUsed AND p_session > 1 THEN PERFORM emaj._dblink_close_cnx('rlbk#' || p_session, v_dblinkSchema); END IF; -- RETURN; -- Trap and record exception during the rollback operation. EXCEPTION WHEN SQLSTATE 'P0001' THEN -- Do not trap the exceptions raised by the function RAISE; WHEN OTHERS THEN -- Otherwise, log the E-Maj rollback abort in emaj_rlbk, if possible PERFORM emaj._rlbk_error(p_rlbkId, 'In _rlbk_session_exec() for session ' || p_session || ': ' || SQLERRM, 'rlbk#' || p_session); RAISE; END; $_rlbk_session_exec$; CREATE OR REPLACE FUNCTION emaj._cleanup_rollback_state() RETURNS INT LANGUAGE plpgsql SECURITY DEFINER SET search_path = pg_catalog, pg_temp AS $_cleanup_rollback_state$ -- This function effectively cleans the rollback states up. It is called by the emaj_cleanup_rollback_state() -- and by other emaj functions. -- The rollbacks whose transaction(s) is/are active are left as is. -- Among the others, those which are also visible in the emaj_hist table are set "COMMITTED", -- while those which are not visible in the emaj_hist table are set "ABORTED". -- Input: no parameter -- Output: number of updated rollback events -- The function is defined as SECURITY DEFINER so that emaj_viewer role can update emaj_rlbk and emaj_hist tables. DECLARE v_nbRlbk INT = 0; v_nbInProgressTx INT; v_newStatus emaj._rlbk_status_enum; r_rlbk RECORD; BEGIN -- Scan all pending rollback events, counting their in-progress sessions. FOR r_rlbk IN SELECT rlbk_id, rlbk_status, rlbk_begin_hist_id, rlbk_nb_session FROM emaj.emaj_rlbk JOIN emaj.emaj_rlbk_session ON (rlbs_rlbk_id = rlbk_id AND rlbs_session = 1) WHERE rlbk_status IN ('PLANNING', 'LOCKING', 'EXECUTING', 'COMPLETED') -- only pending rollback events AND rlbs_txid <> txid_current() -- exclude the current tx, to not process the current -- rollback when start/stop marks are created ORDER BY rlbk_id LOOP -- Get the number of unterminated sessions. SELECT count(*) INTO v_nbInProgressTx FROM emaj.emaj_rlbk_session WHERE rlbs_rlbk_id = r_rlbk.rlbk_id AND NOT txid_visible_in_snapshot(rlbs_txid, txid_current_snapshot()); -- Only process rollback id with no in-progress session. IF v_nbInProgressTx = 0 THEN -- Try to lock the current rlbk_id, but skip it if it is not immediately possible to avoid deadlocks in rare cases. IF EXISTS (SELECT 0 FROM emaj.emaj_rlbk WHERE rlbk_id = r_rlbk.rlbk_id FOR UPDATE SKIP LOCKED ) THEN -- Look at the emaj_hist to find the trace of the rollback begin event. IF EXISTS (SELECT 0 FROM emaj.emaj_hist WHERE hist_id = r_rlbk.rlbk_begin_hist_id ) THEN -- If the emaj_hist rollback_begin event is visible, the rollback transaction has been committed. -- So set the rollback event in emaj_rlbk as "COMMITTED". v_newStatus = 'COMMITTED'; ELSE -- Otherwise, set the rollback event in emaj_rlbk as "ABORTED" v_newStatus = 'ABORTED'; END IF; UPDATE emaj.emaj_rlbk SET rlbk_status = v_newStatus WHERE rlbk_id = r_rlbk.rlbk_id; INSERT INTO emaj.emaj_hist (hist_function, hist_object, hist_wording) VALUES ('CLEANUP_RLBK_STATE', 'Rollback id ' || r_rlbk.rlbk_id, 'set to ' || v_newStatus); v_nbRlbk = v_nbRlbk + 1; END IF; END IF; END LOOP; -- RETURN v_nbRlbk; END; $_cleanup_rollback_state$; CREATE OR REPLACE FUNCTION emaj._verify_all_groups() RETURNS SETOF TEXT LANGUAGE plpgsql AS $_verify_all_groups$ -- The function verifies the consistency of all E-Maj groups. -- It returns a set of error or warning messages for discovered discrepancies. -- If no error is detected, no row is returned. BEGIN -- -- Errors detection. -- -- Check that the postgres version at groups creation time is compatible (i.e. >= 8.4). RETURN QUERY SELECT 'Error: The group "' || group_name || '" has been created with a non compatible postgresql version (' || group_pg_version || '). It must be dropped and recreated.' AS msg 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 ORDER BY msg; -- Check that all application schemas referenced in the emaj_relation table still exist. RETURN QUERY SELECT 'Error: The application schema "' || rel_schema || '" does not exist any more.' AS msg FROM ( SELECT DISTINCT rel_schema FROM emaj.emaj_relation WHERE upper_inf(rel_time_range) EXCEPT SELECT nspname FROM pg_catalog.pg_namespace ) AS t ORDER BY msg; -- Check that all application relations referenced in the emaj_relation table still exist. RETURN QUERY SELECT 'Error: In the group "' || r.rel_group || '", the ' || CASE WHEN t.rel_kind = 'r' THEN 'table "' ELSE 'sequence "' END || t.rel_schema || '"."' || t.rel_tblseq || '" does not exist any more.' AS msg FROM -- all expected application relations ( SELECT rel_schema, rel_tblseq, rel_kind FROM emaj.emaj_relation WHERE upper_inf(rel_time_range) EXCEPT -- minus relations known by postgres SELECT nspname, relname, relkind FROM pg_catalog.pg_class JOIN pg_catalog.pg_namespace ON (pg_namespace.oid = relnamespace) WHERE relkind IN ('r','S') ) AS t JOIN emaj.emaj_relation r ON (t.rel_schema = r.rel_schema AND t.rel_tblseq = r.rel_tblseq AND upper_inf(r.rel_time_range)) ORDER BY t.rel_schema, t.rel_tblseq, 1; -- Check that the log table for all tables referenced in the emaj_relation table still exist. RETURN QUERY SELECT 'Error: In the group "' || rel_group || '", the log table "' || rel_log_schema || '"."' || rel_log_table || '" is not found.' AS msg FROM emaj.emaj_relation WHERE rel_kind = 'r' AND NOT EXISTS (SELECT NULL FROM pg_catalog.pg_class JOIN pg_catalog.pg_namespace ON (pg_namespace.oid = relnamespace) WHERE nspname = rel_log_schema AND relname = rel_log_table ) ORDER BY rel_schema, rel_tblseq, 1; -- Check that the log sequence for all tables referenced in the emaj_relation table still exist. RETURN QUERY SELECT 'Error: In the group "' || rel_group || '", the log sequence "' || rel_log_schema || '"."' || rel_log_sequence || '" is not found.' AS msg FROM emaj.emaj_relation WHERE upper_inf(rel_time_range) AND rel_kind = 'r' AND NOT EXISTS (SELECT NULL FROM pg_catalog.pg_class JOIN pg_catalog.pg_namespace ON (pg_namespace.oid = relnamespace) WHERE nspname = rel_log_schema AND relname = rel_log_sequence ) ORDER BY rel_schema, rel_tblseq, 1; -- Check the log function for each table referenced in the emaj_relation table still exist. RETURN QUERY SELECT 'Error: In the group "' || rel_group || '", the log function "' || rel_log_schema || '"."' || rel_log_function || '" is not found.' AS msg FROM emaj.emaj_relation WHERE upper_inf(rel_time_range) AND rel_kind = 'r' AND NOT EXISTS (SELECT NULL FROM pg_catalog.pg_proc JOIN pg_catalog.pg_namespace ON (pg_namespace.oid = pronamespace) WHERE nspname = rel_log_schema AND proname = rel_log_function ) ORDER BY rel_schema, rel_tblseq, 1; -- Check log and truncate triggers for all tables referenced in the emaj_relation table still exist. -- Start with log triggers. RETURN QUERY SELECT 'Error: In the group "' || rel_group || '", the log trigger "emaj_log_trg" on table "' || rel_schema || '"."' || rel_tblseq || '" is not found.' AS msg FROM emaj.emaj_relation WHERE upper_inf(rel_time_range) AND rel_kind = 'r' AND NOT EXISTS (SELECT NULL FROM pg_catalog.pg_trigger JOIN pg_catalog.pg_class ON (pg_class.oid = tgrelid) JOIN pg_catalog.pg_namespace ON (pg_namespace.oid = relnamespace) WHERE nspname = rel_schema AND relname = rel_tblseq AND tgname = 'emaj_log_trg' ) -- do not issue a row if the application table does not exist, -- this case has been already detected AND EXISTS (SELECT NULL FROM pg_catalog.pg_class JOIN pg_catalog.pg_namespace ON (pg_namespace.oid = relnamespace) WHERE nspname = rel_schema AND relname = rel_tblseq ) ORDER BY rel_schema, rel_tblseq, 1; -- Then truncate triggers. RETURN QUERY SELECT 'Error: In the group "' || rel_group || '", the truncate trigger "emaj_trunc_trg" on table "' || rel_schema || '"."' || rel_tblseq || '" is not found.' AS msg FROM emaj.emaj_relation WHERE upper_inf(rel_time_range) AND rel_kind = 'r' AND NOT EXISTS (SELECT NULL FROM pg_catalog.pg_trigger JOIN pg_catalog.pg_class ON (pg_class.oid = tgrelid) JOIN pg_catalog.pg_namespace ON (pg_namespace.oid = relnamespace) WHERE nspname = rel_schema AND relname = rel_tblseq AND tgname = 'emaj_trunc_trg' ) -- do not issue a row if the application table does not exist, -- this case has been already detected AND EXISTS (SELECT NULL FROM pg_catalog.pg_class JOIN pg_catalog.pg_namespace ON (pg_namespace.oid = relnamespace) WHERE nspname = rel_schema AND relname = rel_tblseq ) ORDER BY rel_schema, rel_tblseq, 1; -- Check that all log tables have a structure consistent with the application tables they reference -- (same columns and same formats). It only returns one row per faulting table. RETURN QUERY SELECT msg FROM (WITH cte_app_tables_columns AS -- application table's columns (SELECT rel_group, rel_schema, rel_tblseq, rel_log_schema, rel_log_table, attname, atttypid, attlen, atttypmod FROM emaj.emaj_relation JOIN pg_catalog.pg_class ON (relname = rel_tblseq) JOIN pg_catalog.pg_namespace ON (pg_namespace.oid = relnamespace AND nspname = rel_schema) JOIN pg_catalog.pg_attribute ON (attrelid = pg_class.oid) WHERE attnum > 0 AND attisdropped = FALSE AND upper_inf(rel_time_range) AND rel_kind = 'r' ), cte_log_tables_columns AS -- log table's columns (SELECT rel_group, rel_schema, rel_tblseq, rel_log_schema, rel_log_table, attname, atttypid, attlen, atttypmod FROM emaj.emaj_relation JOIN pg_catalog.pg_class ON (relname = rel_log_table) JOIN pg_catalog.pg_namespace ON (pg_namespace.oid = relnamespace AND nspname = rel_log_schema) JOIN pg_catalog.pg_attribute ON (attrelid = pg_class.oid) WHERE attnum > 0 AND attisdropped = FALSE AND attnum < rel_emaj_verb_attnum AND upper_inf(rel_time_range) AND rel_kind = 'r' ) SELECT DISTINCT rel_schema, rel_tblseq, 'Error: In the group "' || rel_group || '", the structure of the application table "' || rel_schema || '"."' || rel_tblseq || '" is not coherent with its log table ("' || rel_log_schema || '"."' || rel_log_table || '").' AS msg FROM ( -- application table's columns ( SELECT rel_group, rel_schema, rel_tblseq, rel_log_schema, rel_log_table, attname, atttypid, attlen, atttypmod FROM cte_app_tables_columns EXCEPT -- minus log table's columns SELECT rel_group, rel_schema, rel_tblseq, rel_log_schema, rel_log_table, attname, atttypid, attlen, atttypmod FROM cte_log_tables_columns ) UNION -- log table's columns ( SELECT rel_group, rel_schema, rel_tblseq, rel_log_schema, rel_log_table, attname, atttypid, attlen, atttypmod FROM cte_log_tables_columns EXCEPT -- minus application table's columns SELECT rel_group, rel_schema, rel_tblseq, rel_log_schema, rel_log_table, attname, atttypid, attlen, atttypmod FROM cte_app_tables_columns ) ) AS t -- do not issue a row if the log or application table does not exist, -- these cases have been already detected WHERE (rel_log_schema, rel_log_table) IN (SELECT nspname, relname FROM pg_catalog.pg_class JOIN pg_catalog.pg_namespace ON (pg_namespace.oid = relnamespace) ) AND (rel_schema, rel_tblseq) IN (SELECT nspname, relname FROM pg_catalog.pg_class JOIN pg_catalog.pg_namespace ON (pg_namespace.oid = relnamespace) ) ORDER BY 1,2,3 ) AS t; -- Check that all tables of rollbackable groups have their primary key. RETURN QUERY SELECT 'Error: In the rollbackable group "' || rel_group || '", the table "' || rel_schema || '"."' || rel_tblseq || '" has no primary key any more.' AS msg FROM emaj.emaj_relation JOIN emaj.emaj_group ON (group_name = rel_group) WHERE upper_inf(rel_time_range) AND rel_kind = 'r' AND group_is_rollbackable AND NOT EXISTS (SELECT NULL FROM pg_catalog.pg_class JOIN pg_catalog.pg_namespace ON (pg_namespace.oid = relnamespace) JOIN pg_catalog.pg_constraint ON (connamespace = pg_namespace.oid AND conrelid = pg_class.oid) WHERE nspname = rel_schema AND relname = rel_tblseq AND contype = 'p' ) -- do not issue a row if the application table does not exist, -- this case has been already detected AND EXISTS (SELECT NULL FROM pg_catalog.pg_class JOIN pg_catalog.pg_namespace ON (pg_namespace.oid = relnamespace) WHERE nspname = rel_schema AND relname = rel_tblseq ) ORDER BY rel_schema, rel_tblseq, 1; -- For rollbackable groups, check that no table has been altered as UNLOGGED or dropped and recreated as TEMP table after -- tables groups creation. RETURN QUERY SELECT 'Error: In the rollbackable group "' || rel_group || '", the table "' || rel_schema || '"."' || rel_tblseq || '" is UNLOGGED or TEMP.' AS msg FROM emaj.emaj_relation JOIN emaj.emaj_group ON (group_name = rel_group) JOIN pg_catalog.pg_class ON (relname = rel_tblseq) JOIN pg_catalog.pg_namespace ON (pg_namespace.oid = relnamespace AND nspname = rel_schema) WHERE upper_inf(rel_time_range) AND rel_kind = 'r' AND group_is_rollbackable AND relpersistence <> 'p' ORDER BY rel_schema, rel_tblseq, 1; -- With PG 11-, check that all tables are WITHOUT OIDS (i.e. have not been altered as WITH OIDS after their tables group creation). IF emaj._pg_version_num() < 120000 THEN RETURN QUERY SELECT 'Error: In the rollbackable group "' || rel_group || '", the table "' || rel_schema || '"."' || rel_tblseq || '" is WITH OIDS.' AS msg FROM emaj.emaj_relation JOIN emaj.emaj_group ON (group_name = rel_group) JOIN pg_catalog.pg_class ON (relname = rel_tblseq) JOIN pg_catalog.pg_namespace ON (pg_namespace.oid = relnamespace AND nspname = rel_schema) WHERE upper_inf(rel_time_range) AND rel_kind = 'r' AND group_is_rollbackable AND relhasoids ORDER BY rel_schema, rel_tblseq, 1; END IF; -- Check the primary key structure of all tables belonging to rollbackable groups is unchanged. RETURN QUERY SELECT 'Error: In the rollbackable group "' || rel_group || '", the primary key of the table "' || rel_schema || '"."' || rel_tblseq || '" has changed (' || rel_sql_rlbk_pk_columns || ' => ' || current_pk_columns || ').' AS msg FROM (SELECT rel_schema, rel_tblseq, rel_group, rel_sql_rlbk_pk_columns, string_agg(quote_ident(attname), ',' ORDER BY attnum) AS current_pk_columns FROM emaj.emaj_relation JOIN emaj.emaj_group ON (group_name = rel_group) JOIN pg_catalog.pg_class ON (relname = rel_tblseq) JOIN pg_catalog.pg_namespace ON (pg_namespace.oid = relnamespace AND nspname = rel_schema) JOIN pg_catalog.pg_index ON (indrelid = pg_class.oid) JOIN pg_catalog.pg_attribute ON (pg_attribute.attrelid = pg_index.indrelid) WHERE rel_kind = 'r' AND upper_inf(rel_time_range) AND group_is_rollbackable AND attnum = ANY (indkey) AND indisprimary AND attnum > 0 AND attisdropped = FALSE GROUP BY rel_schema, rel_tblseq, rel_group, rel_sql_rlbk_pk_columns ) AS t WHERE rel_sql_rlbk_pk_columns <> current_pk_columns ORDER BY rel_schema, rel_tblseq, 1; -- Check the array of triggers to ignore at rollback time only contains existing triggers. RETURN QUERY SELECT 'Error: In the rollbackable group "' || rel_group || '", the trigger "' || trg_name || '" for table "' || rel_schema || '"."' || rel_tblseq || '" is missing. ' || 'Use the emaj_modify_table() function to adjust the list of application triggers that should not be' || ' automatically disabled at rollback time.' AS msg FROM (SELECT rel_group, rel_schema, rel_tblseq, unnest(rel_ignored_triggers) AS trg_name FROM emaj.emaj_relation WHERE upper_inf(rel_time_range) AND rel_ignored_triggers IS NOT NULL ) AS t WHERE NOT EXISTS (SELECT NULL FROM pg_catalog.pg_trigger JOIN pg_catalog.pg_class ON (pg_class.oid = tgrelid) JOIN pg_catalog.pg_namespace ON (pg_namespace.oid = relnamespace) WHERE nspname = rel_schema AND relname = rel_tblseq AND tgname = trg_name ) ORDER BY rel_schema, rel_tblseq, 1; -- Check all log tables have the 6 required technical columns. RETURN QUERY SELECT msg FROM (SELECT DISTINCT rel_schema, rel_tblseq, 'Error: In the group "' || rel_group || '", the log table "' || rel_log_schema || '"."' || rel_log_table || '" miss some technical columns (' || string_agg(attname,', ') || ').' AS msg FROM ( SELECT rel_group, rel_schema, rel_tblseq, rel_log_schema, rel_log_table, attname FROM emaj.emaj_relation, (VALUES ('emaj_verb'), ('emaj_tuple'), ('emaj_gid'), ('emaj_changed'), ('emaj_txid'), ('emaj_user')) AS t(attname) WHERE rel_kind = 'r' AND upper_inf(rel_time_range) AND EXISTS (SELECT NULL FROM pg_catalog.pg_namespace JOIN pg_catalog.pg_class ON (relnamespace = pg_namespace.oid) WHERE nspname = rel_log_schema AND relname = rel_log_table ) EXCEPT SELECT rel_group, rel_schema, rel_tblseq, rel_log_schema, rel_log_table, attname FROM emaj.emaj_relation JOIN pg_catalog.pg_class ON (relname = rel_log_table) JOIN pg_catalog.pg_namespace ON (pg_namespace.oid = relnamespace AND nspname = rel_log_schema) JOIN pg_catalog.pg_attribute ON (attrelid = pg_class.oid) WHERE attnum > 0 AND attisdropped = FALSE AND attname IN ('emaj_verb', 'emaj_tuple', 'emaj_gid', 'emaj_changed', 'emaj_txid', 'emaj_user') AND rel_kind = 'r' AND upper_inf(rel_time_range) ) AS t2 GROUP BY rel_group, rel_schema, rel_tblseq, rel_log_schema, rel_log_table ORDER BY 1,2,3 ) AS t; -- -- Warnings detection. -- -- Detect all sequences associated to a serial or a "generated as identity" column have their related table in the same group. RETURN QUERY SELECT msg FROM (WITH serial_dependencies AS (SELECT rs.rel_group AS seq_group, rs.rel_schema AS seq_schema, rs.rel_tblseq AS seq_name, rt.rel_group AS tbl_group, nt.nspname AS tbl_schema, ct.relname AS tbl_name FROM emaj.emaj_relation rs JOIN pg_catalog.pg_class cs ON (cs.relname = rel_tblseq) JOIN pg_catalog.pg_namespace ns ON (ns.oid = cs.relnamespace AND ns.nspname = rel_schema) JOIN pg_catalog.pg_depend ON (pg_depend.objid = cs.oid) JOIN pg_catalog.pg_class ct ON (ct.oid = pg_depend.refobjid) JOIN pg_catalog.pg_namespace nt ON (nt.oid = ct.relnamespace) LEFT OUTER JOIN emaj.emaj_relation rt ON (rt.rel_schema = nt.nspname AND rt.rel_tblseq = ct.relname AND (rt.rel_time_range IS NULL OR upper_inf(rt.rel_time_range))) WHERE rs.rel_kind = 'S' AND upper_inf(rs.rel_time_range) AND pg_depend.classid = pg_depend.refclassid -- the classid et refclassid must be 'pg_class' AND pg_depend.classid = (SELECT oid FROM pg_catalog.pg_class WHERE relname = 'pg_class' ) ) SELECT DISTINCT seq_schema, seq_name, 'Warning: In the group "' || seq_group || '", the sequence "' || seq_schema || '"."' || seq_name || '" is linked to the table "' || tbl_schema || '"."' || tbl_name || '" but this table does not belong to any tables group.' AS msg FROM serial_dependencies WHERE tbl_group IS NULL UNION ALL SELECT DISTINCT seq_schema, seq_name, 'Warning: In the group "' || seq_group || '", the sequence "' || seq_schema || '"."' || seq_name || '" is linked to the table "' || tbl_schema || '"."' || tbl_name || '" but this table belongs to another tables group (' || tbl_group || ').' AS msg FROM serial_dependencies WHERE tbl_group <> seq_group ORDER BY 1,2,3 ) AS t; -- Detect tables linked by a foreign key but not belonging to the same tables group. RETURN QUERY SELECT msg FROM (WITH fk_dependencies AS -- all foreign keys that link 2 tables at least one of both belongs to a tables group (SELECT n.nspname AS tbl_schema, t.relname AS tbl_name, c.conname, nf.nspname AS reftbl_schema, tf.relname AS reftbl_name, r.rel_group AS tbl_group, g.group_is_rollbackable AS tbl_group_is_rollbackable, rf.rel_group AS reftbl_group, gf.group_is_rollbackable AS reftbl_group_is_rollbackable FROM pg_catalog.pg_constraint c JOIN pg_catalog.pg_class t ON (t.oid = c.conrelid) JOIN pg_catalog.pg_namespace n ON (n.oid = t.relnamespace) JOIN pg_catalog.pg_class tf ON (tf.oid = c.confrelid) JOIN pg_catalog.pg_namespace nf ON (nf.oid = tf.relnamespace) LEFT OUTER JOIN emaj.emaj_relation r ON (r.rel_schema = n.nspname AND r.rel_tblseq = t.relname AND upper_inf(r.rel_time_range)) LEFT OUTER JOIN emaj.emaj_group g ON (g.group_name = r.rel_group) LEFT OUTER JOIN emaj.emaj_relation rf ON (rf.rel_schema = nf.nspname AND rf.rel_tblseq = tf.relname AND upper_inf(rf.rel_time_range)) LEFT OUTER JOIN emaj.emaj_group gf ON (gf.group_name = rf.rel_group) WHERE contype = 'f' -- FK constraints only AND (r.rel_group IS NOT NULL OR rf.rel_group IS NOT NULL) -- at least the table or the referenced table belongs to -- a tables group AND t.relkind = 'r' -- only constraint linking true tables, ie. excluding AND tf.relkind = 'r' -- partitionned tables ) SELECT tbl_schema, tbl_name, 'Warning: In the group "' || tbl_group || '", the foreign key "' || conname || '" on the table "' || tbl_schema || '"."' || tbl_name || '" references the table "' || reftbl_schema || '"."' || reftbl_name || '" that does not belong to any group.' AS msg FROM fk_dependencies WHERE tbl_group IS NOT NULL AND tbl_group_is_rollbackable AND reftbl_group IS NULL UNION ALL SELECT tbl_schema, tbl_name, 'Warning: In the group "' || reftbl_group || '", the table "' || reftbl_schema || '"."' || reftbl_name || '" is referenced by the foreign key "' || conname || '" of the table "' || tbl_schema || '"."' || tbl_name || '" that does not belong to any group.' AS msg FROM fk_dependencies WHERE reftbl_group IS NOT NULL AND reftbl_group_is_rollbackable AND tbl_group IS NULL UNION ALL SELECT tbl_schema, tbl_name, 'Warning: In the group "' || tbl_group || '", the foreign key "' || conname || '" on the table "' || tbl_schema || '"."' || tbl_name || '" references the table "' || reftbl_schema || '"."' || reftbl_name || '" that belongs to another group ("' || reftbl_group || '")' AS msg FROM fk_dependencies WHERE tbl_group IS NOT NULL AND reftbl_group IS NOT NULL AND tbl_group <> reftbl_group AND (tbl_group_is_rollbackable OR reftbl_group_is_rollbackable) ORDER BY 1,2,3 ) AS t; -- RETURN; END; $_verify_all_groups$; -- pattern used by the tool that extracts and insert the functions definition ------------------------------------------ -- -- -- event triggers and related functions -- -- -- ------------------------------------------ ------------------------------------ -- -- -- emaj roles and rights -- -- -- ------------------------------------ REVOKE ALL ON ALL FUNCTIONS IN SCHEMA emaj FROM PUBLIC; GRANT ALL ON ALL TABLES IN SCHEMA emaj TO emaj_adm; GRANT ALL ON ALL SEQUENCES IN SCHEMA emaj TO emaj_adm; GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA emaj TO emaj_adm; GRANT SELECT ON ALL TABLES IN SCHEMA emaj TO emaj_viewer; GRANT SELECT ON ALL SEQUENCES IN SCHEMA emaj TO emaj_viewer; REVOKE SELECT ON TABLE emaj.emaj_param FROM emaj_viewer; ------------------------------------ -- -- -- complete the upgrade -- -- -- ------------------------------------ -- Enable the event triggers DO $tmp$ DECLARE v_event_trigger_array TEXT[]; BEGIN -- Build the event trigger names array from the pg_event_trigger table. SELECT coalesce(array_agg(evtname),ARRAY[]::TEXT[]) INTO v_event_trigger_array FROM pg_catalog.pg_event_trigger WHERE evtname LIKE 'emaj%' AND evtenabled = 'D'; -- Call the _enable_event_triggers() function. PERFORM emaj._enable_event_triggers(v_event_trigger_array); END; $tmp$; -- Set comments for all internal functions, -- by directly inserting a row in the pg_description table for all emaj functions that do not have yet a recorded comment. INSERT INTO pg_catalog.pg_description (objoid, classoid, objsubid, description) SELECT pg_proc.oid, pg_class.oid, 0 , 'E-Maj internal function' FROM pg_catalog.pg_proc, pg_catalog.pg_class WHERE pg_class.relname = 'pg_proc' AND pg_proc.oid IN -- list all emaj functions that do not have yet a comment in pg_description (SELECT pg_proc.oid FROM pg_catalog.pg_proc JOIN pg_catalog.pg_namespace ON (pronamespace=pg_namespace.oid) LEFT OUTER JOIN pg_catalog.pg_description ON (pg_description.objoid = pg_proc.oid AND classoid = (SELECT oid FROM pg_catalog.pg_class WHERE relname = 'pg_proc') AND objsubid = 0) WHERE nspname = 'emaj' AND (proname LIKE E'emaj\\_%' OR proname LIKE E'\\_%') AND pg_description.description IS NULL ); -- Update the version id in the emaj_param table. ALTER TABLE emaj.emaj_param DISABLE TRIGGER emaj_param_change_trg; UPDATE emaj.emaj_param SET param_value_text = '4.0.1' WHERE param_key = 'emaj_version'; ALTER TABLE emaj.emaj_param ENABLE TRIGGER emaj_param_change_trg; -- Insert the upgrade end record in the operation history. INSERT INTO emaj.emaj_hist (hist_function, hist_event, hist_object, hist_wording) VALUES ('EMAJ_INSTALL','END','E-Maj 4.0.1', 'Upgrade from 4.0.0 completed'); -- Post installation checks. DO $tmp$ DECLARE 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'); END IF; END; $tmp$; RESET default_tablespace; SET client_min_messages TO default;