Skip to content

Commit

Permalink
v1.2.3 Fixed permission bug in dml/logdel_maker() functions during so…
Browse files Browse the repository at this point in the history
…urce database queue function/table creation.
  • Loading branch information
keithf4 committed Jun 13, 2014
1 parent 131e22f commit 51cd766
Show file tree
Hide file tree
Showing 22 changed files with 5,956 additions and 118 deletions.
13 changes: 13 additions & 0 deletions CHANGELOG
@@ -1,3 +1,16 @@
1.2.3
-- Fixed bug with dml_maker() and logdel_maker() functions where proper permissions where not being granted to the queue table and trigger function.
-- This was happening if an unprivileged role was used in the dblink_mapping_mimeo table. Unprivileged in this sense meaning it could not look up
the permissions in the information_schema.table_privileges view to see all the roles that had write permissions on the given source table.
-- In order to fix this, all future trigger functions for DML-based replication that are put on the source table are given SECURITY DEFINER.
This makes it no longer necessary to look up existing source table permissions as was done before.
-- This also means any future permission changes to source tables will no longer affect writing to the queue table anymore. This should make
administration of DML-based replication source tables easier since additonal privileges on the queue tables no longer have to be managed
manually when source table privileges change.
-- Trigger functions for existing DML-based replication source tables are not fixed. It is advised to edit the trigger function(s) to add
the SECURITY DEFINER flag to make future administration easier.
-- Updated pgtap tests to test when source table owner is different than the dblink_mapping role.

1.2.2
-- New function "check_missing_source_tables()" can show tables that exist on the configured data sources that are not configured for replication.
-- Provides monitoring capability for situations where all tables on source should be replicated.
Expand Down
6 changes: 3 additions & 3 deletions META.json
@@ -1,7 +1,7 @@
{
"name": "mimeo",
"abstract": "Extension for specialized, per-table replication between PostgreSQL databases",
"version": "1.2.2",
"version": "1.2.3",
"maintainer": [
"Keith Fiske <keith@omniti.com>"
],
Expand All @@ -21,9 +21,9 @@
},
"provides": {
"mimeo": {
"file": "sql/mimeo--1.2.2.sql",
"file": "sql/mimeo--1.2.3.sql",
"docfile": "doc/mimeo.md",
"version": "1.2.2",
"version": "1.2.3",
"abstract": "Extension for specialized, per-table replication between PostgreSQL databases"
}
},
Expand Down
9 changes: 5 additions & 4 deletions doc/mimeo.md
Expand Up @@ -10,6 +10,7 @@ Mimeo is a replication extension for copying specific tables in one of several s

**Incremental replication** comes in two forms: Insert Only and Insert/Update Only. This can only be done on a table that has a timestamp or serial/id control column that is set during every insert and/or update. The update replication requires that the source has a primary key. Insert-only replication doesn't require a primary key, just the control column. If the source table ever has rows deleted, this WILL NOT be replicated to the destination.
For time-based incremental replication, systems that do not run in UTC time can have issues during DST changes. To account for this, these maker functions check the timezone of the server and if it is anything but UTC/GMT, it sets dst_active to true in the config table. This causes all replication to pause between 12:30am and 2:30am on the morning of any DST change day. These times can be adjusted if needed using the dst_start and dst_end columns in the refresh_config_inserter or refresh_config_updater table accordingly.
IMPORTANT: If a transaction on the source lasts longer than the interval the incremental jobs run, rows can be missed because the control field's time or id will be the time or id of the transactions' start. Be sure and set a boundary value for your tables that ensures all transactions have completed for that time or integer interval before replication tries to pull its values. The default is 10 minutes for time based and 1 for serial.
Also be aware that if you stop incremental replication permanently on a table, all of the source data may not have reached the destination due to the boundary settings and/or other methods that are used to keep incremental replication in a consistent state. Please double-check that all your source data is on the destination before destroying the source.

**DML replication** replays on the destination every insert, update and delete that happens on the source table. The special "logdel" dml replication does not remove rows that are deleted on the source. Instead it grabs the latest data that was deleted from the source, updates that on the destination and logs a timestamp of when it was deleted from the source (special destination timestamp field is called *mimeo_source_deleted* to try and keep it from conflicting with any existing column names). Be aware that for logdel, if you delete a row and then re-use that primary/unique key value again, you will lose the preserved, deleted row on the destination. Doing otherwise would either violate the key constraint or not replicate the new data.
Expand Down Expand Up @@ -71,8 +72,8 @@ Extension Objects
*dml_maker(p_src_table text, p_dblink_id int, p_dest_table text DEFAULT NULL, p_index boolean DEFAULT true, p_filter text[] DEFAULT NULL, p_condition text DEFAULT NULL, p_pulldata boolean DEFAULT true, p_pk_name text[] DEFAULT NULL, p_pk_type text[] DEFAULT NULL, p_debug boolean DEFAULT false)*
* Function to automatically setup dml replication for a table. See setup instructions above for permissions that are needed on source database. By default source and destination table will have same schema and table names.
* Source table must have a primary key or unique index. Either the primary key or a unique index (first in alphabetical order if more than one) on the source table will be obtained automatically. Columns of primary/unique key cannot be arrays nor can they be an expression.
* The trigger function created on the source table has the SECURITY DEFINER flag set. This allows any writes to the source table to be able to write to the queue table as well.
* If destination table already exists, no data will be pulled from the source. You can use the refresh_dml() 'repull' option to truncate the destination table and grab all the source data.
* The queue table and trigger function on the source database will have permissions set to allow any current roles with write privileges on the source table to use them. If any further privileges are changed on the source table, the queue and trigger function will have to have their privileges adjusted manually.
* Multiple destinations are supported for a single source table but there is a hard limit of 100 destinations. Be aware that doing so places multiple triggers on the source table which will in turn be writing to multiple queue tables to track changes. This can cause noticable performance penalties depending on the level of write traffic on the source table.
* p_dblink_id is the data_source_id from the dblink_mapping_mimeo table for where the source table is located.
* p_dest_table, an optional argument, is to set a custom destination table. Be sure to schema qualify it if needed.
Expand Down Expand Up @@ -100,8 +101,8 @@ Extension Objects
*logdel_maker(p_src_table text, p_dblink_id int, p_dest_table text DEFAULT NULL, p_index boolean DEFAULT true, p_filter text[] DEFAULT NULL, p_condition text DEFAULT NULL, p_pulldata boolean DEFAULT true, p_pk_name text[] DEFAULT NULL, p_pk_type text[] DEFAULT NULL, p_debug boolean DEFAULT false)*
* Function to automatically setup logdel replication for a table. See setup instructions above for permissions that are needed on source database. By default source and destination table will have same schema and table names.
* Source table must have a primary key or unique index. Either the primary key or a unique index (first in alphabetical order if more than one) on the source table will be obtained automatically. Columns of primary/unique key cannot be arrays nor can they be an expression.
* The trigger function created on the source table has the SECURITY DEFINER flag set. This allows any writes to the source table to be able to write to the queue table as well.
* If destination table already exists, no data will be pulled from the source. You can use the refresh_logdel() 'repull' option to truncate the destination table and grab all the source data.
* The queue table and trigger function on the source database will have permissions set to allow any current roles with write privileges on the source table to use them. If any further privileges are changed on the source table, the queue and trigger function will have to have their privileges adjusted manually.
* Multiple destinations are supported for a single source table but there is a hard limit of 100 destinations. Be aware that doing so places multiple triggers on the source table which will in turn be writing to multiple queue tables to track changes. This can cause noticable performance penalties depending on the level of write traffic on the source table.
* p_dblink_id is the data_source_id from the dblink_mapping_mimeo table for where the source table is located.
* p_dest_table, an optional argument, is to set a custom destination table. Be sure to schema qualify it if needed.
Expand Down Expand Up @@ -201,7 +202,7 @@ Extension Objects
*dml_destroyer(p_dest_table text, p_keep_table boolean DEFAULT true)*
* Function to automatically remove a dml replication table from the destination. This will also automatically remove the associated objects from the source database if the dml_maker() function was used to create it.
* p_keep_table is an optional, boolean parameter to say whether you want to keep or destroy your destination database table. Defaults to true to help prevent you accidentally destroying the destination when you didn't mean to.
* Be aware that only the owner of a table can drop triggers, so this function will fail if the source database mimeo role does not own the source table. This is the way PostgreSQL permissions are currently setup and there's nothing I can do about it.
* Be aware that only the owner of a table can drop triggers, so this function will fail if the source database mimeo role does not own the source table. Dropping the mimeo trigger first should allow the destroyer function to run successfully and clean the rest of the objects up. This is the way PostgreSQL permissions are currently setup and there's nothing I can do about it.

*inserter_destroyer(p_dest_table text, p_keep_table boolean DEFAULT true)*
* Function to automatically remove an inserter replication table from the destination.
Expand All @@ -210,7 +211,7 @@ Extension Objects
*logdel_destroyer(p_dest_table text, p_keep_table boolean DEFAULT true)*
* Function to automatically remove a logdel replication table from the destination. This will also automatically remove the associated objects from the source database if the dml_maker() function was used to create it.
* p_keep_table is an optional, boolean parameter to say whether you want to keep or destroy your destination database table. Defaults to true to help prevent you accidentally destroying the destination when you didn't mean to.
* Be aware that only the owner of a table can drop triggers, so this function will fail if the source database mimeo role does not own the source table. This is the way PostgreSQL permissions are currently setup and there's nothing I can do about it.
* Be aware that only the owner of a table can drop triggers, so this function will fail if the source database mimeo role does not own the source table. Dropping the mimeo trigger first should allow the destroyer function to run successfully and clean the rest of the objects up. This is the way PostgreSQL permissions are currently setup and there's nothing I can do about it.

*snapshot_destroyer(p_dest_table text, p_keep_table boolean DEFAULT true)*
* Function to automatically remove a snapshot replication table from the destination.
Expand Down
2 changes: 1 addition & 1 deletion mimeo.control
@@ -1,4 +1,4 @@
default_version = '1.2.2'
default_version = '1.2.3'
comment = 'Extension for specialized, per-table replication between PostgreSQL instances'
requires = 'dblink'
relocatable = false
11 changes: 2 additions & 9 deletions sql/functions/dml_maker.sql
Expand Up @@ -141,7 +141,7 @@ v_remote_q_table := v_remote_q_table || ', processed boolean)';
v_remote_q_index := 'CREATE INDEX ON '||v_source_queue_table||' ('||array_to_string(v_pk_name, ',')||')';

v_pk_counter := 1;
v_trigger_func := 'CREATE FUNCTION '||v_source_queue_function||' RETURNS trigger LANGUAGE plpgsql AS $_$ ';
v_trigger_func := 'CREATE FUNCTION '||v_source_queue_function||' RETURNS trigger LANGUAGE plpgsql SECURITY DEFINER AS $_$ ';
v_trigger_func := v_trigger_func || '
BEGIN IF TG_OP = ''INSERT'' THEN ';
v_pk_value := array_to_string(v_pk_name, ', NEW.');
Expand Down Expand Up @@ -192,14 +192,6 @@ PERFORM gdb(p_debug, 'v_remote_q_index: '||v_remote_q_index);
PERFORM dblink_exec('mimeo_dml', v_remote_q_index);
PERFORM gdb(p_debug, 'v_trigger_func: '||v_trigger_func);
PERFORM dblink_exec('mimeo_dml', v_trigger_func);
-- Grant any current role with write privileges on source table INSERT on the queue table before the trigger is actually created
v_remote_grants_sql := 'SELECT DISTINCT grantee FROM information_schema.table_privileges WHERE table_schema ||''.''|| table_name = '||quote_literal(p_src_table)||' and privilege_type IN (''INSERT'',''UPDATE'',''DELETE'')';
FOR v_row IN SELECT grantee FROM dblink('mimeo_dml', v_remote_grants_sql) t (grantee text)
LOOP
PERFORM dblink_exec('mimeo_dml', 'GRANT USAGE ON SCHEMA @extschema@ TO '||quote_ident(v_row.grantee));
PERFORM dblink_exec('mimeo_dml', 'GRANT INSERT ON TABLE '||v_source_queue_table||' TO '||quote_ident(v_row.grantee));
PERFORM dblink_exec('mimeo_dml', 'GRANT EXECUTE ON FUNCTION '||v_source_queue_function||' TO '||quote_ident(v_row.grantee));
END LOOP;
PERFORM gdb(p_debug, 'v_create_trig: '||v_create_trig);
PERFORM dblink_exec('mimeo_dml', v_create_trig);

Expand Down Expand Up @@ -288,3 +280,4 @@ EXCEPTION
END IF;
END
$$;

11 changes: 1 addition & 10 deletions sql/functions/logdel_maker.sql
Expand Up @@ -172,7 +172,7 @@ SELECT p_table_exists, p_cols, p_cols_n_types FROM manage_dest_table(p_dest_tabl
v_remote_q_table := 'CREATE TABLE '||v_source_queue_table||' ('||array_to_string(v_cols_n_types, ',')||', mimeo_source_deleted timestamptz, processed boolean)';
-- Indexes on queue table created below so the variable can be reused

v_trigger_func := 'CREATE FUNCTION '||v_source_queue_function||' RETURNS trigger LANGUAGE plpgsql AS $_$ DECLARE ';
v_trigger_func := 'CREATE FUNCTION '||v_source_queue_function||' RETURNS trigger LANGUAGE plpgsql SECURITY DEFINER AS $_$ DECLARE ';
v_trigger_func := v_trigger_func || '
v_del_time timestamptz := clock_timestamp(); ';
v_trigger_func := v_trigger_func || '
Expand Down Expand Up @@ -230,14 +230,6 @@ PERFORM gdb(p_debug, 'v_remote_q_index: '||v_remote_q_index);
PERFORM dblink_exec('mimeo_logdel', v_remote_q_index);
PERFORM gdb(p_debug, 'v_trigger_func: '||v_trigger_func);
PERFORM dblink_exec('mimeo_logdel', v_trigger_func);
-- Grant any current role with write privileges on source table INSERT on the queue table before the trigger is actually created
v_remote_grants_sql := 'SELECT DISTINCT grantee FROM information_schema.table_privileges WHERE table_schema ||''.''|| table_name = '||quote_literal(p_src_table)||' and privilege_type IN (''INSERT'',''UPDATE'',''DELETE'')';
FOR v_row IN SELECT grantee FROM dblink('mimeo_logdel', v_remote_grants_sql) t (grantee text)
LOOP
PERFORM dblink_exec('mimeo_logdel', 'GRANT USAGE ON SCHEMA @extschema@ TO '||quote_ident(v_row.grantee));
PERFORM dblink_exec('mimeo_logdel', 'GRANT INSERT ON TABLE '||v_source_queue_table||' TO '||quote_ident(v_row.grantee));
PERFORM dblink_exec('mimeo_logdel', 'GRANT EXECUTE ON FUNCTION '||v_source_queue_function||' TO '||quote_ident(v_row.grantee));
END LOOP;
PERFORM gdb(p_debug, 'v_create_trig: '||v_create_trig);
PERFORM dblink_exec('mimeo_logdel', v_create_trig);

Expand Down Expand Up @@ -294,4 +286,3 @@ EXCEPTION
END
$$;


0 comments on commit 51cd766

Please sign in to comment.