Skip to content

Commit

Permalink
Detect that no partitionned table belong to a tables group. Add regre…
Browse files Browse the repository at this point in the history
…ssion tests to verify that elementary partitions are correctly processed.
  • Loading branch information
beaud76 committed May 25, 2017
1 parent 1f8ced7 commit 478b28a
Show file tree
Hide file tree
Showing 91 changed files with 1,995 additions and 846 deletions.
1 change: 1 addition & 0 deletions CHANGES
Original file line number Diff line number Diff line change
Expand Up @@ -4,6 +4,7 @@ E-Maj - Release notes
------
Enhancements:
- Let E-Maj work with PostgreSQL 10.
- Support elementary partitions of partitionned tables (PostgreSQL 10+).
- The emaj_alter_group() function can process any attribute change
registered in the emaj_group_def table, among priority level, log schema
suffix, emaj names prefix, log data or index tablespace, for relations
Expand Down
2 changes: 1 addition & 1 deletion docs/en/concepts.rst
Original file line number Diff line number Diff line change
Expand Up @@ -6,7 +6,7 @@ E-Maj is built on three main concepts.
Tables Group
************

The **tables group** represents a set of application tables that live at the same rhythm, meaning that their content can be restored as a whole if needed. Typically, it deals with all tables of a database that are updated by one or more sets of programs. Each tables group is defined by a name which must be unique inside its database. By extent, a tables group can also contain application sequences (in the RDBMS sense). Tables and sequences that constitute a tables group can belong to different schemas of the database.
The **tables group** represents a set of **application tables** that live at the same rhythm, meaning that their content can be restored as a whole if needed. Typically, it deals with all tables of a database that are updated by one or more sets of programs. Each tables group is defined by a name which must be unique inside its database. By extent, a tables group can also contain **partitions** of partitionned tables and **sequences**. Tables (including partitions) and sequences that constitute a tables group can belong to different schemas of the database.

At a given time, a tables group is either in a **LOGGING** state or in a **IDLE** state. The *LOGGING* state means that all updates applied on the tables of the group are recorded.

Expand Down
2 changes: 2 additions & 0 deletions docs/en/mainFunctions.rst
Original file line number Diff line number Diff line change
Expand Up @@ -58,6 +58,8 @@ A table or a sequence of a given schema (**grpdef_schema** and **grpdef_tblseq**

All tables assigned to a group not created in *AUDIT_ONLY* mode must have an explicit *primary key* (*PRIMARY KEY* clause in *CREATE TABLE* or *ALTER TABLE*).

E-Maj can process elementary partitions of partitionned tables created with the declarative DDL (with PostgreSQL 10+). They are processed as any other tables. However, as there is no need to protect mother tables, which remain empty, E-Maj refuses to include them in tables groups. All partitions of a partitionned table do not need to belong to a tables group. Partitions of a partitionned table can be assigned to different tables groups.

By their nature, neither *TEMPORARY TABLE* nor *UNLOGGED TABLE* are supported by E-Maj. Tables must also be implicitely or explicitely defined as *WITHOUT OIDS*.

If a sequence is associated to an application table, it must be explicitly declared as member of the same group as its table, so that, in case of rollback, the sequence can be reset to its state at the set mark time.
Expand Down
2 changes: 1 addition & 1 deletion docs/fr/concepts.rst
Original file line number Diff line number Diff line change
Expand Up @@ -6,7 +6,7 @@ E-Maj s'appuie sur trois concepts principaux.
Groupe de tables
****************

Le « **groupe de tables** » (*tables group*) représente un ensemble de tables applicatives qui vivent au même rythme, c'est-à-dire dont, en cas de besoin, le contenu doit être restauré comme un tout. Il s'agit typiquement de toutes les tables d'une base de données mises à jour par un ou plusieurs traitements. Chaque groupe de tables est défini par un nom unique pour la base de données concernée. Par extension, un groupe de tables peut également contenir des séquences applicatives (au sens du SGBD). Les tables et séquences qui constituent un groupe peuvent appartenir à des schémas différents de la base de données.
Le « **groupe de tables** » (*tables group*) représente un ensemble de **tables applicatives** qui vivent au même rythme, c'est-à-dire dont, en cas de besoin, le contenu doit être restauré comme un tout. Il s'agit typiquement de toutes les tables d'une base de données mises à jour par un ou plusieurs traitements. Chaque groupe de tables est défini par un nom unique pour la base de données concernée. Par extension, un groupe de tables peut également contenir des **partitions** de tables partitionnées et des **séquences**. Les tables (incluant les partitions) et séquences qui constituent un groupe peuvent appartenir à des schémas différents de la base de données.

A un instant donné, un groupe de tables est soit dans un état « **actif** » (*LOGGING*), soit dans un état « **inactif** » (*IDLE*). L'état actif signifie que les mises à jour apportées aux tables du groupe sont enregistrées.

Expand Down
2 changes: 2 additions & 0 deletions docs/fr/mainFunctions.rst
Original file line number Diff line number Diff line change
Expand Up @@ -58,6 +58,8 @@ Une table ou une séquence d'un schéma donné (colonnes **grpdef_schema** et **

Toute table appartenant à un groupe de tables non créé en mode *AUDIT_ONLY* doit posséder une clé primaire explicite (clause *PRIMARY KEY* des *CREATE TABLE* ou *ALTER TABLE*).

E-Maj gère les partitions élémentaires de tables partitionnées créées avec le DDL déclaratif (à partir de PostgreSQL 10). Elles sont gérées comme n’importe quelle autre table. En revanche, comme les tables mères restent toujours vides, E-Maj refuse qu’elles soient assignées à un groupe de tables. Toutes les partitions d’une même table partitionnée n’ont pas nécessairement besoin d’être couvertes par E-Maj. Des partitions d’une même table partitionnée peuvent être affectées à des groupes de tables différents.

De par leur nature, ni les tables temporaires (*TEMPORARY TABLE*), ni les tables non tracées (*UNLOGGED TABLE*) ne peuvent être supportées par E-Maj. Les tables doivent aussi être implicitement ou explicitement définies *WITHOUT OIDS*.

Si une séquence est associée à une table applicative, il faut explicitement la déclarer dans le même groupe que sa table. Ainsi, lors d'une opération de rollback, elle sera remise dans l'état où elle se trouvait lors de la pose de la marque servant de référence au rollback.
Expand Down
185 changes: 183 additions & 2 deletions sql/emaj--2.0.1--next_version.sql
Original file line number Diff line number Diff line change
Expand Up @@ -381,12 +381,23 @@ $_check_groups_content$
FROM emaj.emaj_group_def WHERE grpdef_group = ANY(v_groupNames)
EXCEPT
SELECT nspname, relname FROM pg_catalog.pg_class, pg_catalog.pg_namespace
WHERE relnamespace = pg_namespace.oid AND relkind IN ('r','S')
WHERE relnamespace = pg_namespace.oid AND relkind IN ('r','S','p')
ORDER BY 1,2) AS t
LOOP
RAISE WARNING '_check_groups_content: Error, the table or sequence %.% does not exist.', quote_ident(r.grpdef_schema), quote_ident(r.grpdef_tblseq);
v_nbError = v_nbError + 1;
END LOOP;
-- check that no application table is a partitioned table (only elementary partitions can be managed by E-Maj)
FOR r IN
SELECT grpdef_schema, grpdef_tblseq
FROM emaj.emaj_group_def, pg_catalog.pg_class, pg_catalog.pg_namespace
WHERE relnamespace = pg_namespace.oid AND nspname = grpdef_schema AND relname = grpdef_tblseq
AND grpdef_group = ANY(v_groupNames) AND relkind = 'p'
ORDER BY 1,2
LOOP
RAISE WARNING '_check_groups_content: Error, the table %.% is a partitionned table (only elementary partitions are supported by E-Maj).', quote_ident(r.grpdef_schema), quote_ident(r.grpdef_tblseq);
v_nbError = v_nbError + 1;
END LOOP;
-- check no application schema listed for the group in the emaj_group_def table is an E-Maj schema
FOR r IN
SELECT grpdef_schema, grpdef_tblseq
Expand Down Expand Up @@ -3036,7 +3047,6 @@ $emaj_snap_group$
quote_literal(v_fileName) || ' ' || coalesce (v_copyOptions, '');
WHEN 'S' THEN
-- if it is a sequence, the statement has no order by
----TODO add the schema name
IF emaj._pg_version_num() < 100000 THEN
v_stmt= 'COPY (SELECT sequence_name, last_value, start_value, increment_by, max_value, ' ||
'min_value, cache_value, is_cycled, is_called FROM ' || v_fullTableName ||
Expand Down Expand Up @@ -3067,6 +3077,177 @@ $emaj_snap_group$;
COMMENT ON FUNCTION emaj.emaj_snap_group(TEXT,TEXT,TEXT) IS
$$Snaps all application tables and sequences of an E-Maj group into a given directory.$$;

CREATE OR REPLACE FUNCTION emaj.emaj_snap_log_group(v_groupName TEXT, v_firstMark TEXT, v_lastMark TEXT, v_dir TEXT, v_copyOptions TEXT)
RETURNS INT LANGUAGE plpgsql SECURITY DEFINER AS
$emaj_snap_log_group$
-- This function creates a file for each log table belonging to the group.
-- It also creates 2 files containing the state of sequences respectively at start mark and end mark
-- For log tables, files contain all rows related to the time frame, sorted on emaj_gid.
-- For sequences, files are names <group>_sequences_at_<mark>, or <group>_sequences_at_<time> if no
-- end mark is specified. They contain one row per sequence.
-- To do its job, the function performs COPY TO statement, using the options provided by the caller.
-- There is no need for the group not to be logging.
-- As all COPY statements are executed inside a single transaction:
-- - the function can be called while other transactions are running,
-- - the snap files will present a coherent state of tables.
-- It's users responsability :
-- - to create the directory (with proper permissions allowing the cluster to write into) before emaj_snap_log_group function call, and
-- - to maintain its content outside E-maj.
-- Input: group name, the 2 mark names defining a range,
-- the absolute pathname of the directory where the files are to be created,
-- options for COPY TO statements
-- a NULL value or an empty string as first_mark indicates the first recorded mark
-- a NULL value or an empty string can be used as last_mark indicating the current state
-- The keyword 'EMAJ_LAST_MARK' can be used as first or last mark to specify the last set mark.
-- Output: number of processed tables and sequences
-- The function is defined as SECURITY DEFINER so that emaj_adm role can use it.
DECLARE
v_nbTb INT = 0;
r_tblsq RECORD;
v_realFirstMark TEXT;
v_realLastMark TEXT;
v_firstMarkId BIGINT;
v_lastMarkId BIGINT;
v_firstEmajGid BIGINT;
v_lastEmajGid BIGINT;
v_firstMarkTsId BIGINT;
v_lastMarkTsId BIGINT;
v_firstMarkTs TIMESTAMPTZ;
v_lastMarkTs TIMESTAMPTZ;
v_logTableName TEXT;
v_fileName TEXT;
v_conditions TEXT;
v_stmt TEXT;
BEGIN
-- insert begin in the history
INSERT INTO emaj.emaj_hist (hist_function, hist_event, hist_object, hist_wording)
VALUES ('SNAP_LOG_GROUP', 'BEGIN', v_groupName,
CASE WHEN v_firstMark IS NULL OR v_firstMark = '' THEN 'From initial mark' ELSE 'From mark ' || v_firstMark END ||
CASE WHEN v_lastMark IS NULL OR v_lastMark = '' THEN ' to current situation' ELSE ' to mark ' || v_lastMark END || ' towards '
|| v_dir);
-- check that the group is recorded in emaj_group table
PERFORM 0 FROM emaj.emaj_group WHERE group_name = v_groupName;
IF NOT FOUND THEN
RAISE EXCEPTION 'emaj_snap_log_group: group "%" has not been created.', v_groupName;
END IF;
-- check the supplied directory is not null
IF v_dir IS NULL THEN
RAISE EXCEPTION 'emaj_snap_log_group: directory parameter cannot be NULL';
END IF;
-- check the copy options parameter doesn't contain unquoted ; that could be used for sql injection
IF regexp_replace(v_copyOptions,'''.*''','') LIKE '%;%' THEN
RAISE EXCEPTION 'emaj_snap_log_group: invalid COPY options parameter format';
END IF;
-- catch the global sequence value and the timestamp of the first mark
IF v_firstMark IS NOT NULL AND v_firstMark <> '' THEN
-- check and retrieve the global sequence value and the timestamp of the start mark for the group
SELECT emaj._get_mark_name(v_groupName,v_firstMark) INTO v_realFirstMark;
IF v_realFirstMark IS NULL THEN
RAISE EXCEPTION 'emaj_snap_log_group: Start mark "%" is unknown for group "%".', v_firstMark, v_groupName;
END IF;
SELECT mark_id, time_id, time_last_emaj_gid, time_clock_timestamp
INTO v_firstMarkId, v_firstMarkTsId, v_firstEmajGid, v_firstMarkTs
FROM emaj.emaj_mark, emaj.emaj_time_stamp
WHERE mark_time_id = time_id AND mark_group = v_groupName AND mark_name = v_realFirstMark;
ELSE
SELECT mark_name, mark_id, time_id, time_last_emaj_gid, time_clock_timestamp
INTO v_realFirstMark, v_firstMarkId, v_firstMarkTsId, v_firstEmajGid, v_firstMarkTs
FROM emaj.emaj_mark, emaj.emaj_time_stamp
WHERE mark_time_id = time_id AND mark_group = v_groupName ORDER BY mark_id LIMIT 1;
END IF;
IF v_lastMark IS NOT NULL AND v_lastMark <> '' THEN
-- the end mark is supplied
SELECT emaj._get_mark_name(v_groupName,v_lastMark) INTO v_realLastMark;
IF v_realLastMark IS NULL THEN
RAISE EXCEPTION 'emaj_snap_log_group: End mark "%" is unknown for group "%".', v_lastMark, v_groupName;
END IF;
ELSE
-- the end mark is not supplied (look for the current state)
-- temporarily create a mark, without locking tables
SELECT emaj._check_new_mark('TEMP_%', ARRAY[v_groupName]) INTO v_realLastMark;
PERFORM emaj._set_mark_groups(ARRAY[v_groupName], v_realLastMark, false, false);
END IF;
-- catch the global sequence value and timestamp of the last mark
SELECT mark_id, time_id, time_last_emaj_gid, time_clock_timestamp INTO v_lastMarkId, v_lastMarkTsId, v_lastEmajGid, v_lastMarkTs
FROM emaj.emaj_mark, emaj.emaj_time_stamp
WHERE mark_time_id = time_id AND mark_group = v_groupName AND mark_name = v_realLastMark;
-- check that the first_mark < end_mark
IF v_firstMarkId > v_lastMarkId THEN
RAISE EXCEPTION 'emaj_snap_log_group: mark id for "%" (% = %) is greater than mark id for "%" (% = %).', v_realFirstMark, v_firstMarkId, v_firstMarkTs, v_realLastMark, v_lastMarkId, v_lastMarkTs;
END IF;
-- build the conditions on emaj_gid corresponding to this marks frame, used for the COPY statements dumping the tables
v_conditions = 'TRUE';
IF v_firstMark IS NOT NULL AND v_firstMark <> '' THEN
v_conditions = v_conditions || ' AND emaj_gid > '|| v_firstEmajGid;
END IF;
IF v_lastMark IS NOT NULL AND v_lastMark <> '' THEN
v_conditions = v_conditions || ' AND emaj_gid <= '|| v_lastEmajGid;
END IF;
-- process all log tables of the emaj_relation table
FOR r_tblsq IN
SELECT rel_priority, rel_schema, rel_tblseq, rel_kind, rel_log_schema, rel_log_table FROM emaj.emaj_relation
WHERE rel_group = v_groupName ORDER BY rel_priority, rel_schema, rel_tblseq
LOOP
IF r_tblsq.rel_kind = 'r' THEN
-- process tables
-- build names
v_fileName = v_dir || '/' || r_tblsq.rel_schema || '_' || r_tblsq.rel_tblseq || '_log.snap';
v_logTableName = quote_ident(r_tblsq.rel_log_schema) || '.' || quote_ident(r_tblsq.rel_log_table);
-- prepare the execute the COPY statement
v_stmt= 'COPY (SELECT * FROM ' || v_logTableName || ' WHERE ' || v_conditions
|| ' ORDER BY emaj_gid ASC) TO ' || quote_literal(v_fileName)
|| ' ' || coalesce (v_copyOptions, '');
EXECUTE v_stmt;
END IF;
-- for sequences, just adjust the counter
v_nbTb = v_nbTb + 1;
END LOOP;
-- generate the file for sequences state at start mark
v_fileName = v_dir || '/' || v_groupName || '_sequences_at_' || v_realFirstMark;
-- and execute the COPY statement
v_stmt= 'COPY (SELECT emaj_sequence.*' ||
' FROM emaj.emaj_sequence, emaj.emaj_relation' ||
' WHERE sequ_time_id = ' || quote_literal(v_firstMarkTsId) || ' AND ' ||
' rel_kind = ''S'' AND rel_group = ' || quote_literal(v_groupName) || ' AND' ||
' sequ_schema = rel_schema AND sequ_name = rel_tblseq' ||
' ORDER BY sequ_schema, sequ_name) TO ' || quote_literal(v_fileName) || ' ' ||
coalesce (v_copyOptions, '');
EXECUTE v_stmt;
-- generate the full file name for sequences state at end mark
IF v_lastMark IS NOT NULL AND v_lastMark <> '' THEN
v_fileName = v_dir || '/' || v_groupName || '_sequences_at_' || v_realLastMark;
ELSE
v_fileName = v_dir || '/' || v_groupName || '_sequences_at_' || to_char(v_lastMarkTs,'HH24.MI.SS.MS');
END IF;
-- and execute the COPY statement
v_stmt= 'COPY (SELECT emaj_sequence.*' ||
' FROM emaj.emaj_sequence, emaj.emaj_relation' ||
' WHERE sequ_time_id = ' || quote_literal(v_lastMarkTsId) || ' AND ' ||
' rel_kind = ''S'' AND rel_group = ' || quote_literal(v_groupName) || ' AND' ||
' sequ_schema = rel_schema AND sequ_name = rel_tblseq' ||
' ORDER BY sequ_schema, sequ_name) TO ' || quote_literal(v_fileName) || ' ' ||
coalesce (v_copyOptions, '');
EXECUTE v_stmt;
IF v_lastMark IS NULL OR v_lastMark = '' THEN
-- no last mark has been supplied, suppress the just created mark
PERFORM emaj._delete_intermediate_mark_group(v_groupName, v_realLastMark, mark_id, mark_time_id)
FROM emaj.emaj_mark WHERE mark_group = v_groupName AND mark_name = v_realLastMark;
END IF;
-- create the _INFO file to keep general information about the snap operation
EXECUTE 'COPY (SELECT ' ||
quote_literal('E-Maj log tables snap of group ' || v_groupName ||
' between marks ' || v_realFirstMark || ' and ' ||
coalesce(v_realLastMark,'current state') || ' at ' || statement_timestamp()) ||
') TO ' || quote_literal(v_dir || '/_INFO') || ' ' || coalesce (v_copyOptions, '');
-- insert end in the history
INSERT INTO emaj.emaj_hist (hist_function, hist_event, hist_object, hist_wording)
VALUES ('SNAP_LOG_GROUP', 'END', v_groupName, v_nbTb || ' tables/sequences processed');
RETURN v_nbTb;
END;
$emaj_snap_log_group$;
COMMENT ON FUNCTION emaj.emaj_snap_log_group(TEXT,TEXT,TEXT,TEXT,TEXT) IS
$$Snaps all application tables and sequences of an E-Maj group into a given directory.$$;

CREATE OR REPLACE FUNCTION emaj._gen_sql_groups(v_groupNames TEXT[], v_firstMark TEXT, v_lastMark TEXT, v_location TEXT, v_tblseqs TEXT[])
RETURNS BIGINT LANGUAGE plpgsql SECURITY DEFINER SET standard_conforming_strings = ON AS
$_gen_sql_groups$
Expand Down

0 comments on commit 478b28a

Please sign in to comment.