Skip to content

Commit

Permalink
Improve checks of the input json structure when importing parameters.…
Browse files Browse the repository at this point in the history
… A "key" attribute must exist for each parameter and nothing but "key" and "value" attributes must be set. If no "value" attribute is set, or if the "value" is null, the parameter is not inserted into or removed from emaj_param.
  • Loading branch information
beaud76 committed Mar 2, 2020
1 parent b11ffff commit f683d5f
Show file tree
Hide file tree
Showing 17 changed files with 829 additions and 562 deletions.
2 changes: 2 additions & 0 deletions docs/en/otherFunctions.rst
Original file line number Diff line number Diff line change
Expand Up @@ -93,6 +93,8 @@ The file must contain a JSON structure having an attribute named *"parameters"*,
}
]}

If a paramater has no *"value"* attribute or if this attribute is set to *NULL*, the parameter is not inserted into the *emaj_param* table, and is deleted if it already exists in the table. So the parameter’s default value will be used by the *emaj* extension.

The function can directly load a file generated by the *emaj_export_parameters_configuration()* function.

If present, the paramètre of key *"emaj_version"* is not processed.
Expand Down
2 changes: 2 additions & 0 deletions docs/fr/otherFunctions.rst
Original file line number Diff line number Diff line change
Expand Up @@ -92,6 +92,8 @@ Le fichier doit contenir une structure JSON ayant un attribut nommé *"parameter
}
]}

Si un paramètre n’a pas d’attribut *"value"* ou si cet attribut est valorisé à *NULL*, le paramètre n’est pas inséré dans la table *emaj_param*, et est supprimé s’il existait déjà dans la table. En conséquence, la valeur par défaut du paramètre sera utilisée par l’extension *emaj*.

La fonction peut directement charger un fichier généré par la fonction *emaj_export_parameters_configuration()*.

S’il est présent, le paramètre de clé *"emaj_version"* n’est pas traité.
Expand Down
238 changes: 129 additions & 109 deletions sql/emaj--3.2.0--devel.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3842,6 +3842,50 @@ $_gen_sql_groups$
END;
$_gen_sql_groups$;

CREATE OR REPLACE FUNCTION emaj.emaj_export_parameters_configuration()
RETURNS JSON LANGUAGE plpgsql AS
$emaj_export_parameters_configuration$
-- This function returns a JSON formatted structure representing all the parameters registered in the emaj_param table.
-- The function can be called by clients like emaj_web.
-- This is just a wrapper of the internal _export_param_conf() function.
-- Output: the parameters content in JSON format
BEGIN
RETURN emaj._export_param_conf();
END;
$emaj_export_parameters_configuration$;
COMMENT ON FUNCTION emaj.emaj_export_parameters_configuration() IS
$$Generates a json structure describing the E-Maj parameters.$$;

CREATE OR REPLACE FUNCTION emaj.emaj_export_parameters_configuration(v_location TEXT)
RETURNS INT LANGUAGE plpgsql
SECURITY DEFINER SET search_path = pg_catalog, pg_temp AS
$emaj_export_parameters_configuration$
-- This function stores the parameters configuration into a file on the server.
-- The JSON structure is built by the _export_param_conf() function.
-- Output: the number of parameters of the recorded JSON structure.
DECLARE
v_paramsJson JSON;
BEGIN
-- get the json structure
SELECT emaj._export_param_conf() INTO v_paramsJson;
-- store the structure into the provided file name
CREATE TEMP TABLE t (params TEXT);
INSERT INTO t
SELECT line FROM regexp_split_to_table(v_paramsJson::TEXT, '\n') AS line;
BEGIN
EXECUTE format ('COPY t TO %s',
quote_literal(v_location));
EXCEPTION WHEN OTHERS THEN
RAISE EXCEPTION 'emaj_export_parameters_configuration: Unable to write to the % file.', v_location;
END;
DROP TABLE t;
-- return the number of recorded parameters
RETURN json_array_length(v_paramsJson->'parameters');
END;
$emaj_export_parameters_configuration$;
COMMENT ON FUNCTION emaj.emaj_export_parameters_configuration(TEXT) IS
$$Generates and stores in a file a json structure describing the E-Maj parameters.$$;

CREATE OR REPLACE FUNCTION emaj._export_param_conf()
RETURNS JSON LANGUAGE plpgsql AS
$_export_param_conf$
Expand Down Expand Up @@ -3899,115 +3943,6 @@ $_export_param_conf$
END;
$_export_param_conf$;

CREATE OR REPLACE FUNCTION emaj.emaj_export_parameters_configuration()
RETURNS JSON LANGUAGE plpgsql AS
$emaj_export_parameters_configuration$
-- This function returns a JSON formatted structure representing all the parameters registered in the emaj_param table.
-- The function can be called by clients like emaj_web.
-- This is just a wrapper of the internal _export_param_conf() function.
-- Output: the parameters content in JSON format
BEGIN
RETURN emaj._export_param_conf();
END;
$emaj_export_parameters_configuration$;
COMMENT ON FUNCTION emaj.emaj_export_parameters_configuration() IS
$$Generates a json structure describing the E-Maj parameters.$$;

CREATE OR REPLACE FUNCTION emaj.emaj_export_parameters_configuration(v_location TEXT)
RETURNS INT LANGUAGE plpgsql
SECURITY DEFINER SET search_path = pg_catalog, pg_temp AS
$emaj_export_parameters_configuration$
-- This function stores the parameters configuration into a file on the server.
-- The JSON structure is built by the _export_param_conf() function.
-- Output: the number of parameters of the recorded JSON structure.
DECLARE
v_paramsJson JSON;
BEGIN
-- get the json structure
SELECT emaj._export_param_conf() INTO v_paramsJson;
-- store the structure into the provided file name
CREATE TEMP TABLE t (params TEXT);
INSERT INTO t
SELECT line FROM regexp_split_to_table(v_paramsJson::TEXT, '\n') AS line;
BEGIN
EXECUTE format ('COPY t TO %s',
quote_literal(v_location));
EXCEPTION WHEN OTHERS THEN
RAISE EXCEPTION 'emaj_export_parameters_configuration: Unable to write to the % file.', v_location;
END;
DROP TABLE t;
-- return the number of recorded parameters
RETURN json_array_length(v_paramsJson->'parameters');
END;
$emaj_export_parameters_configuration$;
COMMENT ON FUNCTION emaj.emaj_export_parameters_configuration(TEXT) IS
$$Generates and stores in a file a json structure describing the E-Maj parameters.$$;

CREATE OR REPLACE FUNCTION emaj._import_param_conf(v_paramsJson JSON, v_deleteCurrentConf BOOLEAN)
RETURNS INT LANGUAGE plpgsql AS
$_import_param_conf$
-- This function processes a JSON formatted structure representing the E-Maj parameters to load.
-- This structure can have been generated by the emaj_export_parameters_configuration() functions and may have been adapted by the user.
-- If a parameter key is referenced several times, the last entry is the final value recorded into emaj_param.
-- The "emaj_version" parameter key is always left unchanged because it is a constant linked to the extension itself.
-- The expected JSON structure must contain an array like:
-- { "parameters": [
-- { "key": "...", "value": "..." },
-- { ... }
-- ] }
-- Input: - the parameter configuration structure in JSON format
-- - an optional boolean indicating whether the current parameters configuration must be deleted before loading the new parameters
-- Output: the number of inserted or updated parameter keys
DECLARE
v_parameters JSON;
v_nbParam INT;
v_key TEXT;
v_value TEXT;
r_param RECORD;
BEGIN
-- look for the "parameters" json path
v_parameters = v_paramsJson #> '{"parameters"}';
IF v_parameters IS NULL THEN
RAISE EXCEPTION '_import_param_conf: The "parameters" JSON sub-structure has not been found in the supplied structure';
ELSE
IF v_deleteCurrentConf THEN
-- if requested, delete the existing parameters, except the 'emaj_version'
-- (the trigger on emaj_param records the deletions into emaj_hist)
DELETE FROM emaj.emaj_param WHERE param_key <> 'emaj_version';
END IF;
-- process each parameter
v_nbParam = 0;
FOR r_param IN
SELECT param FROM json_array_elements(v_parameters) AS t(param)
WHERE param ->> 'key' <> 'emaj_version'
LOOP
-- get each parameter from the list
v_key = r_param.param ->> 'key';
v_value = r_param.param ->> 'value';
-- check the key is valid.
IF v_key NOT IN ('dblink_user_password', 'history_retention', 'alter_log_table',
'avg_row_rollback_duration', 'avg_row_delete_log_duration', 'avg_fkey_check_duration',
'fixed_step_rollback_duration', 'fixed_table_rollback_duration', 'fixed_dblink_rollback_duration') THEN
RAISE EXCEPTION '_import_param_conf: "%" is not a known E-Maj parameter.', v_key;
END IF;
v_nbParam = v_nbParam + 1;
-- insert or update the parameter in the emaj_param table, selecting the right parameter value column type depending on the key
IF v_key IN ('dblink_user_password', 'alter_log_table') THEN
INSERT INTO emaj.emaj_param (param_key, param_value_text) VALUES (v_key, v_value)
ON CONFLICT (param_key) DO
UPDATE SET param_value_text = v_value WHERE EXCLUDED.param_key = v_key;
ELSIF v_key IN ('history_retention', 'avg_row_rollback_duration', 'avg_row_delete_log_duration', 'avg_fkey_check_duration',
'fixed_step_rollback_duration', 'fixed_table_rollback_duration', 'fixed_dblink_rollback_duration') THEN
INSERT INTO emaj.emaj_param (param_key, param_value_interval) VALUES (v_key, v_value::INTERVAL)
ON CONFLICT (param_key) DO
UPDATE SET param_value_interval = v_value::INTERVAL WHERE EXCLUDED.param_key = v_key;
END IF;
END LOOP;
END IF;
RETURN v_nbParam;
END;
$_import_param_conf$;

CREATE OR REPLACE FUNCTION emaj.emaj_import_parameters_configuration(v_paramsJson JSON, v_deleteCurrentConf BOOLEAN DEFAULT FALSE)
RETURNS INT LANGUAGE plpgsql AS
$emaj_import_parameters_configuration$
Expand Down Expand Up @@ -4083,6 +4018,91 @@ $emaj_import_parameters_configuration$;
COMMENT ON FUNCTION emaj.emaj_import_parameters_configuration(TEXT,BOOLEAN) IS
$$Import E-Maj parameters from a JSON formatted file.$$;

CREATE OR REPLACE FUNCTION emaj._import_param_conf(v_paramsJson JSON, v_deleteCurrentConf BOOLEAN)
RETURNS INT LANGUAGE plpgsql AS
$_import_param_conf$
-- This function processes a JSON formatted structure representing the E-Maj parameters to load.
-- This structure can have been generated by the emaj_export_parameters_configuration() functions and may have been adapted by the user.
-- If a parameter key is referenced several times, the last entry is the final value recorded into emaj_param.
-- The "emaj_version" parameter key is always left unchanged because it is a constant linked to the extension itself.
-- The expected JSON structure must contain an array like:
-- { "parameters": [
-- { "key": "...", "value": "..." },
-- { ... }
-- ] }
-- Input: - the parameter configuration structure in JSON format
-- - an optional boolean indicating whether the current parameters configuration must be deleted before loading the new parameters
-- Output: the number of inserted or updated parameter keys
DECLARE
v_parameters JSON;
v_errorList TEXT;
v_nbParam INT;
v_key TEXT;
v_value TEXT;
r_param RECORD;
BEGIN
-- look for the "parameters" json path
v_parameters = v_paramsJson #> '{"parameters"}';
IF v_parameters IS NULL THEN
RAISE EXCEPTION '_import_param_conf: The "parameters" JSON sub-structure has not been found in the supplied structure';
ELSE
IF v_deleteCurrentConf THEN
-- if requested, delete the existing parameters, except the 'emaj_version'
-- (the trigger on emaj_param records the deletions into emaj_hist)
DELETE FROM emaj.emaj_param WHERE param_key <> 'emaj_version';
END IF;
-- process each parameter
v_nbParam = 0;
FOR r_param IN
SELECT param FROM json_array_elements(v_parameters) AS t(param)
LOOP
-- get each parameter from the list
v_key = r_param.param ->> 'key';
v_value = r_param.param ->> 'value';
v_nbParam = v_nbParam + 1;
-- check the "key" attribute exists in the json structure
IF v_key IS NULL THEN
RAISE EXCEPTION '_import_param_conf: the #% parameter has no "key" attribute or a "key" set to null.', v_nbParam;
END IF;
-- check that the structure only contains "key" and "value" attributes
SELECT string_agg(key, ', ') INTO v_errorList FROM (
SELECT key FROM json_object_keys(r_param.param) AS x(key)
WHERE key NOT IN ('key', 'value')
) AS t;
IF v_errorList IS NOT NULL THEN
RAISE EXCEPTION '_import_param_conf: attributes % are not allowed.', v_errorList;
END IF;
-- check the key is valid.
IF v_key NOT IN ('emaj_version', 'dblink_user_password', 'history_retention', 'alter_log_table',
'avg_row_rollback_duration', 'avg_row_delete_log_duration', 'avg_fkey_check_duration',
'fixed_step_rollback_duration', 'fixed_table_rollback_duration', 'fixed_dblink_rollback_duration') THEN
RAISE EXCEPTION '_import_param_conf: "%" is not a known E-Maj parameter.', v_key;
END IF;
-- exclude the 'emaj_version' entry that cannot be changed
IF v_key <> 'emaj_version' THEN
-- if there is no value to set, deleted the parameter, if it exists
IF v_value IS NULL THEN
DELETE FROM emaj.emaj_param WHERE param_key = v_key;
ELSE
-- insert or update the parameter in the emaj_param table, selecting the right parameter value column type depending on the key
IF v_key IN ('dblink_user_password', 'alter_log_table') THEN
INSERT INTO emaj.emaj_param (param_key, param_value_text) VALUES (v_key, v_value)
ON CONFLICT (param_key) DO
UPDATE SET param_value_text = v_value WHERE EXCLUDED.param_key = v_key;
ELSIF v_key IN ('history_retention', 'avg_row_rollback_duration', 'avg_row_delete_log_duration', 'avg_fkey_check_duration',
'fixed_step_rollback_duration', 'fixed_table_rollback_duration', 'fixed_dblink_rollback_duration') THEN
INSERT INTO emaj.emaj_param (param_key, param_value_interval) VALUES (v_key, v_value::INTERVAL)
ON CONFLICT (param_key) DO
UPDATE SET param_value_interval = v_value::INTERVAL WHERE EXCLUDED.param_key = v_key;
END IF;
END IF;
END IF;
END LOOP;
END IF;
RETURN v_nbParam;
END;
$_import_param_conf$;

CREATE OR REPLACE FUNCTION emaj._verify_all_groups()
RETURNS SETOF TEXT LANGUAGE plpgsql AS
$_verify_all_groups$
Expand Down

0 comments on commit f683d5f

Please sign in to comment.