Skip to content

Commit

Permalink
Replace 5 cases of NOT IN (subquery), by a NOT EXISTS (). This does n…
Browse files Browse the repository at this point in the history
…ot change the query meaning because in all these cases the subquery could not process NULL data. But it is safer to code this way, to avoid potential trouble in the future.
  • Loading branch information
beaud76 committed May 31, 2019
1 parent 7670969 commit 8659d3e
Show file tree
Hide file tree
Showing 4 changed files with 101 additions and 53 deletions.
36 changes: 24 additions & 12 deletions sql/emaj--3.0.0--devel.sql
Original file line number Diff line number Diff line change
Expand Up @@ -463,7 +463,7 @@ $_dblink_open_cnx$
-- - param_key = 'dblink_user_password',
-- - param_value_text = 'user=<user> password=<password>' with the rules that apply to usual libPQ connect strings
-- The password can be omited if the connection doesn't require it.
-- The dblink_connect_u is used to open the connection so that emaj_adm but non superuser roles can access the
-- The dblink_connect_u is used to open the connection so that emaj_adm but non superuser roles can access the
-- cluster even when no password is required to log on.
-- Input: connection name
-- Output: integer status return.
Expand Down Expand Up @@ -681,9 +681,11 @@ $_check_conf_groups$
format('in the group %s, the table or sequence %s.%s does not exist.', quote_ident(grpdef_group), quote_ident(grpdef_schema), quote_ident(grpdef_tblseq))
FROM emaj.emaj_group_def
WHERE grpdef_group = ANY(v_groupNames)
AND (grpdef_schema, grpdef_tblseq) NOT IN (
SELECT nspname, relname FROM pg_catalog.pg_class, pg_catalog.pg_namespace
WHERE relnamespace = pg_namespace.oid AND relkind IN ('r','S','p'));
AND NOT EXISTS (
SELECT 0 FROM pg_catalog.pg_class, pg_catalog.pg_namespace
WHERE relnamespace = pg_namespace.oid
AND grpdef_schema = nspname AND grpdef_tblseq = relname
AND relkind IN ('r','S','p'));
---- check that no application table is a partitioned table (only elementary partitions can be managed by E-Maj)
RETURN QUERY
SELECT 2, 1, grpdef_group, grpdef_schema, grpdef_tblseq, NULL::TEXT,
Expand Down Expand Up @@ -1980,8 +1982,10 @@ $_alter_plan$
AND rel_group = ANY (v_groupNames)
AND grpdef_group = ANY (v_groupNames)
-- exclude relations that will have been removed in a previous step
AND (rel_schema, rel_tblseq) NOT IN (
SELECT altr_schema, altr_tblseq FROM emaj.emaj_alter_plan WHERE altr_time_id = v_timeId AND altr_step IN ('REMOVE_TBL', 'REMOVE_SEQ'));
AND NOT EXISTS (
SELECT 0 FROM emaj.emaj_alter_plan
WHERE altr_schema = rel_schema AND altr_tblseq = rel_tblseq
AND altr_time_id = v_timeId AND altr_step IN ('REMOVE_TBL', 'REMOVE_SEQ'));
-- determine the groups that will be reset (i.e. those in IDLE state)
INSERT INTO emaj.emaj_alter_plan (altr_time_id, altr_step, altr_schema, altr_tblseq, altr_group)
SELECT v_timeId, 'RESET_GROUP', '', '', group_name
Expand All @@ -1999,8 +2003,10 @@ $_alter_plan$
AND rel_kind = 'r'
AND coalesce(rel_log_dat_tsp,'') <> coalesce(grpdef_log_dat_tsp,'')
-- exclude tables that will have been repaired in a previous step
AND (rel_schema, rel_tblseq) NOT IN (
SELECT altr_schema, altr_tblseq FROM emaj.emaj_alter_plan WHERE altr_time_id = v_timeId AND altr_step = 'REPAIR_TBL');
AND NOT EXISTS (
SELECT 0 FROM emaj.emaj_alter_plan
WHERE altr_schema = rel_schema AND altr_tblseq = rel_tblseq
AND altr_time_id = v_timeId AND altr_step = 'REPAIR_TBL');
-- determine the tables whose log data tablespace in emaj_group_def has changed
INSERT INTO emaj.emaj_alter_plan (altr_time_id, altr_step, altr_schema, altr_tblseq, altr_group, altr_priority, altr_new_group)
SELECT v_timeId, 'CHANGE_TBL_LOG_INDEX_TSP', rel_schema, rel_tblseq, rel_group, grpdef_priority,
Expand All @@ -2012,8 +2018,12 @@ $_alter_plan$
AND rel_kind = 'r'
AND coalesce(rel_log_idx_tsp,'') <> coalesce(grpdef_log_idx_tsp,'')
-- exclude tables that will have been repaired in a previous step
AND (rel_schema, rel_tblseq) NOT IN (
SELECT altr_schema, altr_tblseq FROM emaj.emaj_alter_plan WHERE altr_time_id = v_timeId AND altr_step = 'REPAIR_TBL');
---- AND (rel_schema, rel_tblseq) NOT IN (
---- SELECT altr_schema, altr_tblseq FROM emaj.emaj_alter_plan WHERE altr_time_id = v_timeId AND altr_step = 'REPAIR_TBL');
AND NOT EXISTS (-----(rel_schema, rel_tblseq) NOT IN (
SELECT 0 FROM emaj.emaj_alter_plan
WHERE altr_schema = rel_schema AND altr_tblseq = rel_tblseq
AND altr_time_id = v_timeId AND altr_step = 'REPAIR_TBL');
-- determine the tables or sequences that change their group ownership
INSERT INTO emaj.emaj_alter_plan (altr_time_id, altr_step, altr_schema, altr_tblseq, altr_group, altr_priority, altr_new_group)
SELECT v_timeId, CAST(CASE WHEN rel_kind = 'r' THEN 'MOVE_TBL' ELSE 'MOVE_SEQ' END AS emaj._alter_step_enum),
Expand Down Expand Up @@ -4814,8 +4824,10 @@ $_adjust_group_properties$
-- adjust the group_has_waiting_changes column, only when needed
modified_group AS (
UPDATE emaj.emaj_group SET group_has_waiting_changes = NOT group_has_waiting_changes
WHERE group_has_waiting_changes = FALSE AND group_name IN (SELECT group_name FROM group_with_changes)
OR group_has_waiting_changes = TRUE AND group_name NOT IN (SELECT group_name FROM group_with_changes)
WHERE (group_has_waiting_changes = FALSE
AND group_name IN (SELECT group_name FROM group_with_changes))
OR (group_has_waiting_changes = TRUE
AND NOT EXISTS (SELECT 0 FROM group_with_changes WHERE group_with_changes.group_name = emaj_group.group_name))
RETURNING group_name, group_has_waiting_changes
),
-- insert a row in the history for each flag change
Expand Down
34 changes: 23 additions & 11 deletions sql/emaj--devel.sql
Original file line number Diff line number Diff line change
Expand Up @@ -1037,9 +1037,11 @@ $_check_conf_groups$
format('in the group %s, the table or sequence %s.%s does not exist.', quote_ident(grpdef_group), quote_ident(grpdef_schema), quote_ident(grpdef_tblseq))
FROM emaj.emaj_group_def
WHERE grpdef_group = ANY(v_groupNames)
AND (grpdef_schema, grpdef_tblseq) NOT IN (
SELECT nspname, relname FROM pg_catalog.pg_class, pg_catalog.pg_namespace
WHERE relnamespace = pg_namespace.oid AND relkind IN ('r','S','p'));
AND NOT EXISTS (
SELECT 0 FROM pg_catalog.pg_class, pg_catalog.pg_namespace
WHERE relnamespace = pg_namespace.oid
AND grpdef_schema = nspname AND grpdef_tblseq = relname
AND relkind IN ('r','S','p'));
---- check that no application table is a partitioned table (only elementary partitions can be managed by E-Maj)
RETURN QUERY
SELECT 2, 1, grpdef_group, grpdef_schema, grpdef_tblseq, NULL::TEXT,
Expand Down Expand Up @@ -3268,8 +3270,10 @@ $_alter_plan$
AND rel_group = ANY (v_groupNames)
AND grpdef_group = ANY (v_groupNames)
-- exclude relations that will have been removed in a previous step
AND (rel_schema, rel_tblseq) NOT IN (
SELECT altr_schema, altr_tblseq FROM emaj.emaj_alter_plan WHERE altr_time_id = v_timeId AND altr_step IN ('REMOVE_TBL', 'REMOVE_SEQ'));
AND NOT EXISTS (
SELECT 0 FROM emaj.emaj_alter_plan
WHERE altr_schema = rel_schema AND altr_tblseq = rel_tblseq
AND altr_time_id = v_timeId AND altr_step IN ('REMOVE_TBL', 'REMOVE_SEQ'));
-- determine the groups that will be reset (i.e. those in IDLE state)
INSERT INTO emaj.emaj_alter_plan (altr_time_id, altr_step, altr_schema, altr_tblseq, altr_group)
SELECT v_timeId, 'RESET_GROUP', '', '', group_name
Expand All @@ -3287,8 +3291,10 @@ $_alter_plan$
AND rel_kind = 'r'
AND coalesce(rel_log_dat_tsp,'') <> coalesce(grpdef_log_dat_tsp,'')
-- exclude tables that will have been repaired in a previous step
AND (rel_schema, rel_tblseq) NOT IN (
SELECT altr_schema, altr_tblseq FROM emaj.emaj_alter_plan WHERE altr_time_id = v_timeId AND altr_step = 'REPAIR_TBL');
AND NOT EXISTS (
SELECT 0 FROM emaj.emaj_alter_plan
WHERE altr_schema = rel_schema AND altr_tblseq = rel_tblseq
AND altr_time_id = v_timeId AND altr_step = 'REPAIR_TBL');
-- determine the tables whose log data tablespace in emaj_group_def has changed
INSERT INTO emaj.emaj_alter_plan (altr_time_id, altr_step, altr_schema, altr_tblseq, altr_group, altr_priority, altr_new_group)
SELECT v_timeId, 'CHANGE_TBL_LOG_INDEX_TSP', rel_schema, rel_tblseq, rel_group, grpdef_priority,
Expand All @@ -3300,8 +3306,12 @@ $_alter_plan$
AND rel_kind = 'r'
AND coalesce(rel_log_idx_tsp,'') <> coalesce(grpdef_log_idx_tsp,'')
-- exclude tables that will have been repaired in a previous step
AND (rel_schema, rel_tblseq) NOT IN (
SELECT altr_schema, altr_tblseq FROM emaj.emaj_alter_plan WHERE altr_time_id = v_timeId AND altr_step = 'REPAIR_TBL');
---- AND (rel_schema, rel_tblseq) NOT IN (
---- SELECT altr_schema, altr_tblseq FROM emaj.emaj_alter_plan WHERE altr_time_id = v_timeId AND altr_step = 'REPAIR_TBL');
AND NOT EXISTS (-----(rel_schema, rel_tblseq) NOT IN (
SELECT 0 FROM emaj.emaj_alter_plan
WHERE altr_schema = rel_schema AND altr_tblseq = rel_tblseq
AND altr_time_id = v_timeId AND altr_step = 'REPAIR_TBL');
-- determine the tables or sequences that change their group ownership
INSERT INTO emaj.emaj_alter_plan (altr_time_id, altr_step, altr_schema, altr_tblseq, altr_group, altr_priority, altr_new_group)
SELECT v_timeId, CAST(CASE WHEN rel_kind = 'r' THEN 'MOVE_TBL' ELSE 'MOVE_SEQ' END AS emaj._alter_step_enum),
Expand Down Expand Up @@ -7580,8 +7590,10 @@ $_adjust_group_properties$
-- adjust the group_has_waiting_changes column, only when needed
modified_group AS (
UPDATE emaj.emaj_group SET group_has_waiting_changes = NOT group_has_waiting_changes
WHERE group_has_waiting_changes = FALSE AND group_name IN (SELECT group_name FROM group_with_changes)
OR group_has_waiting_changes = TRUE AND group_name NOT IN (SELECT group_name FROM group_with_changes)
WHERE (group_has_waiting_changes = FALSE
AND group_name IN (SELECT group_name FROM group_with_changes))
OR (group_has_waiting_changes = TRUE
AND NOT EXISTS (SELECT 0 FROM group_with_changes WHERE group_with_changes.group_name = emaj_group.group_name))
RETURNING group_name, group_has_waiting_changes
),
-- insert a row in the history for each flag change
Expand Down
34 changes: 23 additions & 11 deletions sql/emaj-devel.sql
Original file line number Diff line number Diff line change
Expand Up @@ -1044,9 +1044,11 @@ $_check_conf_groups$
format('in the group %s, the table or sequence %s.%s does not exist.', quote_ident(grpdef_group), quote_ident(grpdef_schema), quote_ident(grpdef_tblseq))
FROM emaj.emaj_group_def
WHERE grpdef_group = ANY(v_groupNames)
AND (grpdef_schema, grpdef_tblseq) NOT IN (
SELECT nspname, relname FROM pg_catalog.pg_class, pg_catalog.pg_namespace
WHERE relnamespace = pg_namespace.oid AND relkind IN ('r','S','p'));
AND NOT EXISTS (
SELECT 0 FROM pg_catalog.pg_class, pg_catalog.pg_namespace
WHERE relnamespace = pg_namespace.oid
AND grpdef_schema = nspname AND grpdef_tblseq = relname
AND relkind IN ('r','S','p'));
---- check that no application table is a partitioned table (only elementary partitions can be managed by E-Maj)
RETURN QUERY
SELECT 2, 1, grpdef_group, grpdef_schema, grpdef_tblseq, NULL::TEXT,
Expand Down Expand Up @@ -3275,8 +3277,10 @@ $_alter_plan$
AND rel_group = ANY (v_groupNames)
AND grpdef_group = ANY (v_groupNames)
-- exclude relations that will have been removed in a previous step
AND (rel_schema, rel_tblseq) NOT IN (
SELECT altr_schema, altr_tblseq FROM emaj.emaj_alter_plan WHERE altr_time_id = v_timeId AND altr_step IN ('REMOVE_TBL', 'REMOVE_SEQ'));
AND NOT EXISTS (
SELECT 0 FROM emaj.emaj_alter_plan
WHERE altr_schema = rel_schema AND altr_tblseq = rel_tblseq
AND altr_time_id = v_timeId AND altr_step IN ('REMOVE_TBL', 'REMOVE_SEQ'));
-- determine the groups that will be reset (i.e. those in IDLE state)
INSERT INTO emaj.emaj_alter_plan (altr_time_id, altr_step, altr_schema, altr_tblseq, altr_group)
SELECT v_timeId, 'RESET_GROUP', '', '', group_name
Expand All @@ -3294,8 +3298,10 @@ $_alter_plan$
AND rel_kind = 'r'
AND coalesce(rel_log_dat_tsp,'') <> coalesce(grpdef_log_dat_tsp,'')
-- exclude tables that will have been repaired in a previous step
AND (rel_schema, rel_tblseq) NOT IN (
SELECT altr_schema, altr_tblseq FROM emaj.emaj_alter_plan WHERE altr_time_id = v_timeId AND altr_step = 'REPAIR_TBL');
AND NOT EXISTS (
SELECT 0 FROM emaj.emaj_alter_plan
WHERE altr_schema = rel_schema AND altr_tblseq = rel_tblseq
AND altr_time_id = v_timeId AND altr_step = 'REPAIR_TBL');
-- determine the tables whose log data tablespace in emaj_group_def has changed
INSERT INTO emaj.emaj_alter_plan (altr_time_id, altr_step, altr_schema, altr_tblseq, altr_group, altr_priority, altr_new_group)
SELECT v_timeId, 'CHANGE_TBL_LOG_INDEX_TSP', rel_schema, rel_tblseq, rel_group, grpdef_priority,
Expand All @@ -3307,8 +3313,12 @@ $_alter_plan$
AND rel_kind = 'r'
AND coalesce(rel_log_idx_tsp,'') <> coalesce(grpdef_log_idx_tsp,'')
-- exclude tables that will have been repaired in a previous step
AND (rel_schema, rel_tblseq) NOT IN (
SELECT altr_schema, altr_tblseq FROM emaj.emaj_alter_plan WHERE altr_time_id = v_timeId AND altr_step = 'REPAIR_TBL');
---- AND (rel_schema, rel_tblseq) NOT IN (
---- SELECT altr_schema, altr_tblseq FROM emaj.emaj_alter_plan WHERE altr_time_id = v_timeId AND altr_step = 'REPAIR_TBL');
AND NOT EXISTS (-----(rel_schema, rel_tblseq) NOT IN (
SELECT 0 FROM emaj.emaj_alter_plan
WHERE altr_schema = rel_schema AND altr_tblseq = rel_tblseq
AND altr_time_id = v_timeId AND altr_step = 'REPAIR_TBL');
-- determine the tables or sequences that change their group ownership
INSERT INTO emaj.emaj_alter_plan (altr_time_id, altr_step, altr_schema, altr_tblseq, altr_group, altr_priority, altr_new_group)
SELECT v_timeId, CAST(CASE WHEN rel_kind = 'r' THEN 'MOVE_TBL' ELSE 'MOVE_SEQ' END AS emaj._alter_step_enum),
Expand Down Expand Up @@ -7587,8 +7597,10 @@ $_adjust_group_properties$
-- adjust the group_has_waiting_changes column, only when needed
modified_group AS (
UPDATE emaj.emaj_group SET group_has_waiting_changes = NOT group_has_waiting_changes
WHERE group_has_waiting_changes = FALSE AND group_name IN (SELECT group_name FROM group_with_changes)
OR group_has_waiting_changes = TRUE AND group_name NOT IN (SELECT group_name FROM group_with_changes)
WHERE (group_has_waiting_changes = FALSE
AND group_name IN (SELECT group_name FROM group_with_changes))
OR (group_has_waiting_changes = TRUE
AND NOT EXISTS (SELECT 0 FROM group_with_changes WHERE group_with_changes.group_name = emaj_group.group_name))
RETURNING group_name, group_has_waiting_changes
),
-- insert a row in the history for each flag change
Expand Down

0 comments on commit 8659d3e

Please sign in to comment.