Skip to content

Commit

Permalink
In log tables, change the emaj_tuple value for TRUNCATE statements, b…
Browse files Browse the repository at this point in the history
…y setting an empty string instead of a NULL. In log tables, set the emaj_verb and emaj_tuple columns NOT NULL. Transform the unique index on log tables into primary key. This allows E-Maj log tables to be member of logical replication publication, without aborting at rollback time for a lack of replica identity.
  • Loading branch information
beaud76 committed Mar 16, 2021
1 parent 7ff6323 commit 36ada39
Show file tree
Hide file tree
Showing 32 changed files with 545 additions and 483 deletions.
2 changes: 2 additions & 0 deletions CHANGES.md
Original file line number Diff line number Diff line change
Expand Up @@ -34,6 +34,8 @@ E-Maj - Change log
###Bug fixes:###
* Set the E-Maj triggers as ALWAYS TRIGGER so that they can be fired by a
logical replication changes stream within a subscription.
* Transform the unique index on log tables into primary key. This allows
E-Maj log tables to be member of logical replication publication.
* Administrator were able to use tablespaces to store log tables and/or
indexes, without being granted any CREATE privilege on these tablespaces.

Expand Down
4 changes: 2 additions & 2 deletions docs/en/logTables.rst
Original file line number Diff line number Diff line change
Expand Up @@ -9,13 +9,13 @@ Standart structure
The structure of log tables is directly derived from the structure of the related application tables. The log tables contain the same columns with the same type. But they also have some additional technical columns:

* emaj_verb : type of the SQL verb that generated the update (*INS*, *UPD*, *DEL*, *TRU*)
* emaj_tuple : row version (*OLD* for *DEL*, *UPD* and *TRU* ; *NEW* for *INS* and *UPD* ; NULL for *TRUNCATE* events)
* emaj_tuple : row version (*OLD* for *DEL*, *UPD* and *TRU* ; *NEW* for *INS* and *UPD* ; empty string for *TRUNCATE* events)
* emaj_gid : log row identifier
* emaj_changed : log row insertion timestamp
* emaj_txid : transaction id (the PostgreSQL *txid*) that performed the update
* emaj_user : connection role that performed the update

When a *TRUNCATE* statement is executed for a table, each row of this table is recorded (with *emaj_verb = TRU* and *emaj_tuple = OLD*). A row is added, with *emaj_verb = TRU*, the other columns and *emaj_tuple* being set to NULL. This row is used by the sql scripts generation.
When a *TRUNCATE* statement is executed for a table, each row of this table is recorded (with *emaj_verb = TRU* and *emaj_tuple = OLD*). A row is added, with *emaj_verb = TRU*, *emaj_tuple = ''*, the other columns being set to NULL. This row is used by the sql scripts generation.

.. _addLogColumns:

Expand Down
2 changes: 2 additions & 0 deletions docs/en/upgrade.rst
Original file line number Diff line number Diff line change
Expand Up @@ -175,3 +175,5 @@ Version specific details:
* The procedure that upgrades a version 2.3.1 into 3.0.0 changes the structure of log tables: both *emaj_client_ip* and *emaj_client_port* columns are not created anymore. Existing log tables are not modified. Only the new log tables are impacted. But the administrator can :ref:`add these columns<addLogColumns>`, by using the *'alter_log_tables'* parameter.

* The procedure that upgrades a version 3.0.0 into 3.1.0 renames existing log objects. This leads to locking the application tables, which may generate conflicts with the parallel use of these tables. This procedure also issues a warning message indicating that the changes in E-Maj rollback functions regarding the application triggers processing may require changes in user’s procedures.

* The procedure that upgrades a version 3.4.0 into 4.0.0 updates the log tables content for TRUNCATE recorded statements. The upgrade duration depends on the global log tables size.
4 changes: 2 additions & 2 deletions docs/fr/logTables.rst
Original file line number Diff line number Diff line change
Expand Up @@ -9,13 +9,13 @@ Structure standard
Les tables de log ont une structure qui découle directement des tables applicatives dont elles enregistrent les mises à jour. Elles contiennent les mêmes colonnes avec les mêmes types. Mais elles possèdent aussi quelques colonnes techniques complémentaires :

* emaj_verb : type de verbe SQL ayant généré la mise à jour (*INS*, *UPD*, *DEL*, *TRU*)
* emaj_tuple : version des lignes (*OLD* pour les *DEL*, *UPD* et *TRU* ; *NEW* pour *INS* et *UPD* ; NULL pour les événements *TRUNCATE*)
* emaj_tuple : version des lignes (*OLD* pour les *DEL*, *UPD* et *TRU* ; *NEW* pour *INS* et *UPD* ; chaîne vide pour les événements *TRUNCATE*)
* emaj_gid : identifiant de la ligne de log
* emaj_changed : date et heure de l'insertion de la ligne dans la table de log
* emaj_txid : identifiant de la transaction à l'origine de la mise à jour (*txid* PostgreSQL)
* emaj_user : rôle de connexion à l'origine de la mise à jour

Lorsqu’une requête SQL *TRUNCATE* est exécutée sur une table, chaque ligne présente dans la table est enregistrée (avec *emaj_verb = TRU* et *emaj_tuple = OLD*). Une ligne est ajoutée avec *emaj_verb = TRU*, les colonnes de la table source et *emaj_tuple* étant positionnées à NULL. Cette ligne est utilisée pour la génération de scripts SQL.
Lorsqu’une requête SQL *TRUNCATE* est exécutée sur une table, chaque ligne présente dans la table est enregistrée (avec *emaj_verb = TRU* et *emaj_tuple = OLD*). Une ligne est ajoutée avec *emaj_verb = TRU*, *emaj_tuple = ''*, les colonnes de la table source étant positionnées à NULL. Cette ligne est utilisée pour la génération de scripts SQL.

.. _addLogColumns:

Expand Down
2 changes: 2 additions & 0 deletions docs/fr/upgrade.rst
Original file line number Diff line number Diff line change
Expand Up @@ -176,3 +176,5 @@ Spécificités liées aux versions :
* La procédure de mise à jour d’une version 2.3.1 en version 3.0.0 change la structure des tables de log : les 2 colonnes *emaj_client_ip* et *emaj_client_port* ne sont plus créées. Les tables de log existantes ne sont pas modifiées. Seules les nouvelles tables de log sont impactées. Mais il est possible à l’administrateur :ref:`d’ajouter ces deux colonnes<addLogColumns>`, en utilisant le paramètre *'alter_log_tables'*.

* La procédure de mise à jour d’une version 3.0.0 en version 3.1.0 renomme les objets de log existants. Ceci conduit à une pose de verrou sur chaque table applicative, qui peut entrer en conflit avec des accès concurrents sur les tables. La procédure de mise à jour génère également un message d’alerte indiquant que les changements dans la gestion des triggers applicatifs par les fonctions de rollback E-Maj peuvent nécessiter des modifications dans les procédures utilisateurs.

* La procédure de mise à jour d’une version 3.4.0 en version 4.0.0 modifie le contenu des tables de log pour les enregistrements des requêtes *TRUNCATE*. La durée de la mise à jour dépend donc de la taille globale des tables de log.
56 changes: 40 additions & 16 deletions sql/emaj--3.4.0--devel.sql
Original file line number Diff line number Diff line change
Expand Up @@ -1345,8 +1345,8 @@ $_truncate_trigger_fnct$
WHERE rel_schema = TG_TABLE_SCHEMA
AND rel_tblseq = TG_TABLE_NAME
AND upper_inf(rel_time_range);
-- log the TRU event into the log table (with emaj_tuple set to NULL)
EXECUTE format('INSERT INTO %s (emaj_verb) VALUES (''TRU'')',
-- log the TRU event into the log table (with emaj_tuple set to an empty string)
EXECUTE format('INSERT INTO %s (emaj_verb, emaj_tuple) VALUES (''TRU'', '''')',
v_fullLogTableName);
-- log all rows from the table
EXECUTE format('INSERT INTO %s SELECT *, ''TRU'', ''OLD'' FROM ONLY %I.%I ',
Expand Down Expand Up @@ -2772,19 +2772,20 @@ $_create_tbl$
v_sequenceName = quote_ident(v_logSchema) || '.' || quote_ident(v_baseSequenceName);
-- prepare TABLESPACE clauses for data and index
v_dataTblSpace = coalesce('TABLESPACE ' || quote_ident(p_logDatTsp),'');
v_idxTblSpace = coalesce('TABLESPACE ' || quote_ident(p_logIdxTsp),'');
v_idxTblSpace = coalesce('USING INDEX TABLESPACE ' || quote_ident(p_logIdxTsp),'');
-- create the log table: it looks like the application table, with some additional technical columns
EXECUTE format('DROP TABLE IF EXISTS %s',
v_logTableName);
EXECUTE format('CREATE TABLE %s (LIKE %s,'
' emaj_verb VARCHAR(3),'
' emaj_tuple VARCHAR(3),'
' emaj_verb VARCHAR(3) NOT NULL,'
' emaj_tuple VARCHAR(3) NOT NULL,'
' emaj_gid BIGINT NOT NULL DEFAULT nextval(''emaj.emaj_global_seq''),'
' emaj_changed TIMESTAMPTZ DEFAULT clock_timestamp(),'
' emaj_txid BIGINT DEFAULT txid_current(),'
' emaj_user VARCHAR(32) DEFAULT session_user'
' emaj_user VARCHAR(32) DEFAULT session_user,'
' CONSTRAINT %s PRIMARY KEY (emaj_gid, emaj_tuple) %s'
' ) %s',
v_logTableName, v_fullTableName, v_dataTblSpace);
v_logTableName, v_fullTableName, v_logIdxName, v_idxTblSpace, v_dataTblSpace);
-- get the attnum of the emaj_verb column
SELECT attnum INTO STRICT v_attnum
FROM pg_catalog.pg_attribute
Expand All @@ -2801,9 +2802,6 @@ $_create_tbl$
EXECUTE format('ALTER TABLE %s %s',
v_logTableName, v_alter_log_table_param);
END IF;
-- create the index on the log table
EXECUTE format('CREATE UNIQUE INDEX %s ON %s(emaj_gid, emaj_tuple)',
v_logIdxName, v_logTableName, v_idxTblSpace);
-- set the index associated to the primary key as cluster index (It may be useful for CLUSTER command)
EXECUTE format('ALTER TABLE ONLY %s CLUSTER ON %s',
v_logTableName, v_logIdxName);
Expand Down Expand Up @@ -3353,9 +3351,11 @@ $_move_tbl$
BEGIN
-- get the current relation characteristics
SELECT rel_log_schema, rel_log_table, rel_log_index, rel_log_sequence,
coalesce('TABLESPACE ' || quote_ident(rel_log_dat_tsp),''), coalesce('TABLESPACE ' || quote_ident(rel_log_idx_tsp),'')
coalesce('TABLESPACE ' || quote_ident(rel_log_dat_tsp),''),
coalesce('USING INDEX TABLESPACE ' || quote_ident(rel_log_idx_tsp),'')
INTO v_logSchema, v_currentLogTable, v_currentLogIndex, v_logSequence,
v_dataTblSpace, v_idxTblSpace
v_dataTblSpace,
v_idxTblSpace
FROM emaj.emaj_relation
WHERE rel_schema = p_schema
AND rel_tblseq = p_table
Expand All @@ -3382,9 +3382,9 @@ $_move_tbl$
-- create the new log table, by copying the just renamed table structure
EXECUTE format('CREATE TABLE %I.%I (LIKE %I.%I INCLUDING DEFAULTS) %s',
v_logSchema, v_currentLogTable, v_logSchema, v_currentLogTable || v_namesSuffix, v_dataTblSpace);
-- create the index on the new log table
EXECUTE format('CREATE UNIQUE INDEX %I ON %I.%I(emaj_gid, emaj_tuple) %s',
v_currentLogIndex, v_logSchema, v_currentLogTable, v_idxTblSpace);
-- add the primary key
EXECUTE format('ALTER TABLE %I.%I ADD CONSTRAiNT %I PRIMARY KEY (emaj_gid, emaj_tuple) %s',
v_logSchema, v_currentLogTable, v_currentLogIndex, v_idxTblSpace);
-- set the index associated to the primary key as cluster index. It may be useful for CLUSTER command.
EXECUTE format('ALTER TABLE ONLY %I.%I CLUSTER ON %I',
v_logSchema, v_currentLogTable, v_currentLogIndex);
Expand Down Expand Up @@ -4645,7 +4645,7 @@ $_gen_sql_tbl$
' LEFT OUTER JOIN %s n ON n.emaj_gid = o.emaj_gid'
' AND (n.emaj_verb = ''UPD'' AND n.emaj_tuple = ''NEW'')'
' WHERE NOT (o.emaj_verb = ''UPD'' AND o.emaj_tuple = ''NEW'')'
' AND NOT (o.emaj_verb = ''TRU'' AND o.emaj_tuple IS NOT NULL)'
' AND NOT (o.emaj_verb = ''TRU'' AND o.emaj_tuple <> '''')'
' AND %s',
v_rqInsert, v_rqUpdate, v_rqDelete, v_rqTruncate, v_logTableName, v_logTableName, v_conditions);
GET DIAGNOSTICS v_nbSQL = ROW_COUNT;
Expand Down Expand Up @@ -12036,6 +12036,30 @@ $tmp$
END;
$tmp$;

--
-- Adjust the log tables content for the TRU recorded verbs (NULL -> '') and transform their index into Primary Key
--
DO
$tmp$
DECLARE
r_log RECORD;
BEGIN
FOR r_log IN
SELECT rel_log_schema, rel_log_table, rel_log_index
FROM emaj.emaj_relation
WHERE rel_kind = 'r'
ORDER BY 1,2
LOOP
EXECUTE format('UPDATE %I.%I SET emaj_tuple = '''' WHERE emaj_tuple IS NULL',
r_log.rel_log_schema, r_log.rel_log_table);
EXECUTE format('ALTER TABLE %I.%I ALTER COLUMN emaj_tuple SET NOT NULL, ALTER COLUMN emaj_verb SET NOT NULL',
r_log.rel_log_schema, r_log.rel_log_table);
EXECUTE format('ALTER TABLE %I.%I ADD PRIMARY KEY USING INDEX %I',
r_log.rel_log_schema, r_log.rel_log_table, r_log.rel_log_index);
END LOOP;
END;
$tmp$;

--
-- Set the currently enabled E-Maj log or truncate triggers as ALWAYS triggers (instead of ORIGIN triggers)
--
Expand Down
32 changes: 16 additions & 16 deletions sql/emaj--devel.sql
Original file line number Diff line number Diff line change
Expand Up @@ -1614,8 +1614,8 @@ $_truncate_trigger_fnct$
WHERE rel_schema = TG_TABLE_SCHEMA
AND rel_tblseq = TG_TABLE_NAME
AND upper_inf(rel_time_range);
-- log the TRU event into the log table (with emaj_tuple set to NULL)
EXECUTE format('INSERT INTO %s (emaj_verb) VALUES (''TRU'')',
-- log the TRU event into the log table (with emaj_tuple set to an empty string)
EXECUTE format('INSERT INTO %s (emaj_verb, emaj_tuple) VALUES (''TRU'', '''')',
v_fullLogTableName);
-- log all rows from the table
EXECUTE format('INSERT INTO %s SELECT *, ''TRU'', ''OLD'' FROM ONLY %I.%I ',
Expand Down Expand Up @@ -3047,19 +3047,20 @@ $_create_tbl$
v_sequenceName = quote_ident(v_logSchema) || '.' || quote_ident(v_baseSequenceName);
-- prepare TABLESPACE clauses for data and index
v_dataTblSpace = coalesce('TABLESPACE ' || quote_ident(p_logDatTsp),'');
v_idxTblSpace = coalesce('TABLESPACE ' || quote_ident(p_logIdxTsp),'');
v_idxTblSpace = coalesce('USING INDEX TABLESPACE ' || quote_ident(p_logIdxTsp),'');
-- create the log table: it looks like the application table, with some additional technical columns
EXECUTE format('DROP TABLE IF EXISTS %s',
v_logTableName);
EXECUTE format('CREATE TABLE %s (LIKE %s,'
' emaj_verb VARCHAR(3),'
' emaj_tuple VARCHAR(3),'
' emaj_verb VARCHAR(3) NOT NULL,'
' emaj_tuple VARCHAR(3) NOT NULL,'
' emaj_gid BIGINT NOT NULL DEFAULT nextval(''emaj.emaj_global_seq''),'
' emaj_changed TIMESTAMPTZ DEFAULT clock_timestamp(),'
' emaj_txid BIGINT DEFAULT txid_current(),'
' emaj_user VARCHAR(32) DEFAULT session_user'
' emaj_user VARCHAR(32) DEFAULT session_user,'
' CONSTRAINT %s PRIMARY KEY (emaj_gid, emaj_tuple) %s'
' ) %s',
v_logTableName, v_fullTableName, v_dataTblSpace);
v_logTableName, v_fullTableName, v_logIdxName, v_idxTblSpace, v_dataTblSpace);
-- get the attnum of the emaj_verb column
SELECT attnum INTO STRICT v_attnum
FROM pg_catalog.pg_attribute
Expand All @@ -3076,9 +3077,6 @@ $_create_tbl$
EXECUTE format('ALTER TABLE %s %s',
v_logTableName, v_alter_log_table_param);
END IF;
-- create the index on the log table
EXECUTE format('CREATE UNIQUE INDEX %s ON %s(emaj_gid, emaj_tuple)',
v_logIdxName, v_logTableName, v_idxTblSpace);
-- set the index associated to the primary key as cluster index (It may be useful for CLUSTER command)
EXECUTE format('ALTER TABLE ONLY %s CLUSTER ON %s',
v_logTableName, v_logIdxName);
Expand Down Expand Up @@ -3628,9 +3626,11 @@ $_move_tbl$
BEGIN
-- get the current relation characteristics
SELECT rel_log_schema, rel_log_table, rel_log_index, rel_log_sequence,
coalesce('TABLESPACE ' || quote_ident(rel_log_dat_tsp),''), coalesce('TABLESPACE ' || quote_ident(rel_log_idx_tsp),'')
coalesce('TABLESPACE ' || quote_ident(rel_log_dat_tsp),''),
coalesce('USING INDEX TABLESPACE ' || quote_ident(rel_log_idx_tsp),'')
INTO v_logSchema, v_currentLogTable, v_currentLogIndex, v_logSequence,
v_dataTblSpace, v_idxTblSpace
v_dataTblSpace,
v_idxTblSpace
FROM emaj.emaj_relation
WHERE rel_schema = p_schema
AND rel_tblseq = p_table
Expand All @@ -3657,9 +3657,9 @@ $_move_tbl$
-- create the new log table, by copying the just renamed table structure
EXECUTE format('CREATE TABLE %I.%I (LIKE %I.%I INCLUDING DEFAULTS) %s',
v_logSchema, v_currentLogTable, v_logSchema, v_currentLogTable || v_namesSuffix, v_dataTblSpace);
-- create the index on the new log table
EXECUTE format('CREATE UNIQUE INDEX %I ON %I.%I(emaj_gid, emaj_tuple) %s',
v_currentLogIndex, v_logSchema, v_currentLogTable, v_idxTblSpace);
-- add the primary key
EXECUTE format('ALTER TABLE %I.%I ADD CONSTRAiNT %I PRIMARY KEY (emaj_gid, emaj_tuple) %s',
v_logSchema, v_currentLogTable, v_currentLogIndex, v_idxTblSpace);
-- set the index associated to the primary key as cluster index. It may be useful for CLUSTER command.
EXECUTE format('ALTER TABLE ONLY %I.%I CLUSTER ON %I',
v_logSchema, v_currentLogTable, v_currentLogIndex);
Expand Down Expand Up @@ -4920,7 +4920,7 @@ $_gen_sql_tbl$
' LEFT OUTER JOIN %s n ON n.emaj_gid = o.emaj_gid'
' AND (n.emaj_verb = ''UPD'' AND n.emaj_tuple = ''NEW'')'
' WHERE NOT (o.emaj_verb = ''UPD'' AND o.emaj_tuple = ''NEW'')'
' AND NOT (o.emaj_verb = ''TRU'' AND o.emaj_tuple IS NOT NULL)'
' AND NOT (o.emaj_verb = ''TRU'' AND o.emaj_tuple <> '''')'
' AND %s',
v_rqInsert, v_rqUpdate, v_rqDelete, v_rqTruncate, v_logTableName, v_logTableName, v_conditions);
GET DIAGNOSTICS v_nbSQL = ROW_COUNT;
Expand Down

0 comments on commit 36ada39

Please sign in to comment.