Skip to content

Commit

Permalink
fix: allow replica identity using index to work with non-search-path …
Browse files Browse the repository at this point in the history
…schemas. add unit test
  • Loading branch information
keithf4 committed Dec 20, 2024
1 parent 2052caf commit 41bc480
Show file tree
Hide file tree
Showing 4 changed files with 151 additions and 24 deletions.
27 changes: 16 additions & 11 deletions sql/functions/inherit_replica_identity.sql
Original file line number Diff line number Diff line change
Expand Up @@ -7,15 +7,19 @@ v_child_partition_index text;
v_child_partition_oid oid;
v_parent_oid oid;
v_parent_replident char;
v_parent_replident_index name;
v_parent_replident_oid oid;
v_replident_string text;
v_sql text;

BEGIN

/*
* Set the given child table's replica identity to the same as the parent
NOTE: Replication identity not automatically inherited as of PG16 (revisit in future versions)
NOTE: Replication identity not automatically inherited as of PG16 (revisit in future versions).
ANOTHER NOTE: Replica identity with USING INDEX only works with indexes that actually exist on the parent,
not indexes that are inherited from the template. Since the replica identity could be defined on both
the template and the parent at the same time , there's no way to tell which one is the "right" one.
Using the parent table's replica identity index at least ensures the index inheritance relationship.
*/

SELECT c.oid
Expand All @@ -29,8 +33,8 @@ AND c.relname = p_parent_tablename;

IF v_parent_replident = 'i' THEN

SELECT c.relname
INTO v_parent_replident_index
SELECT c.oid
INTO v_parent_replident_oid
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_index i ON i.indexrelid = c.oid
WHERE i.indrelid = v_parent_oid
Expand All @@ -43,18 +47,19 @@ IF v_parent_replident = 'i' THEN
WHERE n.nspname = p_parent_schemaname
AND c.relname = p_child_tablename;

SELECT partition_index.indexrelid::regclass::text
SELECT partition_index_name.relname
INTO v_child_partition_index
FROM pg_index parent_index -- parent index
INNER JOIN pg_inherits index_inheritance ON (index_inheritance.inhparent=parent_index.indexrelid) -- parent partition index
INNER JOIN pg_index partition_index ON (index_inheritance.inhrelid=partition_index.indexrelid) -- connection between parent and partition indexes
INNER JOIN pg_class partition_table ON (partition_table.oid=partition_index.indrelid) -- connection between child table and child index
FROM pg_index parent_index
INNER JOIN pg_catalog.pg_inherits index_inheritance ON (index_inheritance.inhparent=parent_index.indexrelid) -- parent index inheritance
INNER JOIN pg_catalog.pg_index partition_index ON (index_inheritance.inhrelid=partition_index.indexrelid) -- connection between parent index and child index
INNER JOIN pg_catalog.pg_class partition_index_name ON (partition_index.indexrelid=partition_index_name.oid) -- get child index name
INNER JOIN pg_catalog.pg_class partition_table ON (partition_table.oid=partition_index.indrelid) -- connection between child table and child index
WHERE partition_table.oid=v_child_partition_oid -- child partition table
AND parent_index.indexrelid=v_parent_replident_index::regclass; -- parent partition index
AND parent_index.indexrelid=v_parent_replident_oid; -- parent partition index

END IF;

RAISE DEBUG 'inherit_replica_ident: v_parent_oid: %, v_parent_replident: %, v_parent_replident_index: %, v_child_partition_oid: %, v_child_partition_index: %', v_parent_oid, v_parent_replident, v_parent_replident_index, v_child_partition_oid, v_child_partition_index;
RAISE DEBUG 'inherit_replica_ident: v_parent_oid: %, v_parent_replident: %, v_parent_replident_oid: %, v_child_partition_oid: %, v_child_partition_index: %', v_parent_oid, v_parent_replident, v_parent_replident_oid, v_child_partition_oid, v_child_partition_index;

IF v_parent_replident != 'd' THEN
CASE v_parent_replident
Expand Down
Original file line number Diff line number Diff line change
@@ -1,6 +1,6 @@
-- ########## TIME DAILY TESTS ##########
-- Other tests:
-- Test that replica identity is inherited
-- Test that replica identity FULL is inherited
-- Ensure partition_data_proc can move data out of default when its in publication

\set ON_ERROR_ROLLBACK 1
Expand Down
118 changes: 118 additions & 0 deletions test/test-time-replica-identity-using-index.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,118 @@
-- ########## TIME DAILY TESTS ##########
-- Other tests:
-- Test that replica identity USING INDEX is inherited. Note this only works with indexes that actually exist on the parent
-- Ensure partition_data_proc can move data out of default when its in publication

\set ON_ERROR_ROLLBACK 1
\set ON_ERROR_STOP true

BEGIN;
SELECT set_config('search_path','partman, public',false);

SELECT plan(34);

CREATE SCHEMA partman_test;

CREATE TABLE partman_test.time_taptest_table
(col1 int NOT NULL
, col2 text default 'stuff'
, col3 timestamptz NOT NULL DEFAULT now())
PARTITION BY RANGE (col3);
CREATE UNIQUE INDEX time_taptest_table_unq ON partman_test.time_taptest_table (col1, col3);
ALTER TABLE partman_test.time_taptest_table REPLICA IDENTITY USING INDEX time_taptest_table_unq;

-- Create publication before child tables to check it was inherited
CREATE PUBLICATION partman_test_publication FOR TABLE partman_test.time_taptest_table;

SELECT create_parent('partman_test.time_taptest_table', 'col3', '1 day');

INSERT INTO partman_test.time_taptest_table (col1, col3) VALUES (generate_series(1,10), CURRENT_TIMESTAMP);

SELECT is_partitioned('partman_test', 'time_taptest_table', 'Check that time_taptest_table is natively partitioned');
SELECT has_table('partman', 'template_partman_test_time_taptest_table', 'Check that default template table was created');

SELECT has_table('partman_test', 'time_taptest_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYYMMDD'), 'Check time_taptest_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYYMMDD')||' exists');
SELECT has_table('partman_test', 'time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYYMMDD'),
'Check time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYYMMDD')||' exists');
SELECT has_table('partman_test', 'time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYYMMDD'),
'Check time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYYMMDD')||' exists');
SELECT has_table('partman_test', 'time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYYMMDD'),
'Check time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYYMMDD')||' exists');
SELECT has_table('partman_test', 'time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYYMMDD'),
'Check time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYYMMDD')||' exists');
SELECT hasnt_table('partman_test', 'time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYYMMDD'),
'Check time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYYMMDD')||' does not exist');
SELECT has_table('partman_test', 'time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'1 day'::interval, 'YYYYMMDD'),
'Check time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'1 day'::interval, 'YYYYMMDD')||' exists');
SELECT has_table('partman_test', 'time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'2 days'::interval, 'YYYYMMDD'),
'Check time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'2 days'::interval, 'YYYYMMDD')||' exists');
SELECT has_table('partman_test', 'time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'3 days'::interval, 'YYYYMMDD'),
'Check time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'3 days'::interval, 'YYYYMMDD')||' exists');
SELECT has_table('partman_test', 'time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'4 days'::interval, 'YYYYMMDD'),
'Check time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'4 days'::interval, 'YYYYMMDD')||' exists');
SELECT hasnt_table('partman_test', 'time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'5 days'::interval, 'YYYYMMDD'),
'Check time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'5 days'::interval, 'YYYYMMDD')||' does not exist');

SELECT results_eq('SELECT partition_tablename FROM partman.show_partitions(''partman_test.time_taptest_table'') LIMIT 1', ARRAY['time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'4 days'::interval, 'YYYYMMDD')], 'Check that -4 day old table table is oldest');

SELECT results_eq('SELECT c.relreplident::text FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = ''partman_test'' AND c.relname = ''time_taptest_table_default''', ARRAY['i'], 'Check that replica identity was inherited to time_taptest_table_default' );

SELECT results_eq('SELECT c.relreplident::text FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = ''partman_test'' AND c.relname = ''time_taptest_table_p''||to_char(CURRENT_TIMESTAMP, ''YYYYMMDD'')', ARRAY['i'], 'Check that replica identity was inherited to time_taptest_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYYMMDD') );

SELECT results_eq('SELECT c.relreplident::text FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = ''partman_test'' AND c.relname = ''time_taptest_table_p''||to_char(CURRENT_TIMESTAMP-''1 day''::interval, ''YYYYMMDD'')', ARRAY['i'], 'Check that replica identity was inherited to time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'1 day'::interval, 'YYYYMMDD') );

SELECT results_eq('SELECT c.relreplident::text FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = ''partman_test'' AND c.relname = ''time_taptest_table_p''||to_char(CURRENT_TIMESTAMP-''2 day''::interval, ''YYYYMMDD'')', ARRAY['i'], 'Check that replica identity was inherited to time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'2 day'::interval, 'YYYYMMDD') );

SELECT results_eq('SELECT c.relreplident::text FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = ''partman_test'' AND c.relname = ''time_taptest_table_p''||to_char(CURRENT_TIMESTAMP-''3 day''::interval, ''YYYYMMDD'')', ARRAY['i'], 'Check that replica identity was inherited to time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'3 day'::interval, 'YYYYMMDD') );

SELECT results_eq('SELECT c.relreplident::text FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = ''partman_test'' AND c.relname = ''time_taptest_table_p''||to_char(CURRENT_TIMESTAMP-''4 day''::interval, ''YYYYMMDD'')', ARRAY['i'], 'Check that replica identity was inherited to time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'4 day'::interval, 'YYYYMMDD') );


SELECT results_eq('SELECT c.relreplident::text FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = ''partman_test'' AND c.relname = ''time_taptest_table_p''||to_char(CURRENT_TIMESTAMP+''1 day''::interval, ''YYYYMMDD'')', ARRAY['i'], 'Check that replica identity was inherited to time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYYMMDD') );

SELECT results_eq('SELECT c.relreplident::text FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = ''partman_test'' AND c.relname = ''time_taptest_table_p''||to_char(CURRENT_TIMESTAMP+''2 day''::interval, ''YYYYMMDD'')', ARRAY['i'], 'Check that replica identity was inherited to time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'2 day'::interval, 'YYYYMMDD') );

SELECT results_eq('SELECT c.relreplident::text FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = ''partman_test'' AND c.relname = ''time_taptest_table_p''||to_char(CURRENT_TIMESTAMP+''3 day''::interval, ''YYYYMMDD'')', ARRAY['i'], 'Check that replica identity was inherited to time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'3 day'::interval, 'YYYYMMDD') );

SELECT results_eq('SELECT c.relreplident::text FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = ''partman_test'' AND c.relname = ''time_taptest_table_p''||to_char(CURRENT_TIMESTAMP+''4 day''::interval, ''YYYYMMDD'')', ARRAY['i'], 'Check that replica identity was inherited to time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'4 day'::interval, 'YYYYMMDD') );

INSERT INTO partman_test.time_taptest_table (col1, col3) VALUES (generate_series(11,20), CURRENT_TIMESTAMP + '1 day'::interval);
INSERT INTO partman_test.time_taptest_table (col1, col3) VALUES (generate_series(21,25), CURRENT_TIMESTAMP + '2 days'::interval);
INSERT INTO partman_test.time_taptest_table (col1, col3) VALUES (generate_series(26,30), CURRENT_TIMESTAMP + '3 days'::interval);
INSERT INTO partman_test.time_taptest_table (col1, col3) VALUES (generate_series(31,37), CURRENT_TIMESTAMP + '4 days'::interval);

SELECT run_maintenance();

SELECT results_eq('SELECT c.relreplident::text FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = ''partman_test'' AND c.relname = ''time_taptest_table_p''||to_char(CURRENT_TIMESTAMP+''5 day''::interval, ''YYYYMMDD'')', ARRAY['i'], 'Check that replica identity was inherited to time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'5 day'::interval, 'YYYYMMDD') );

SELECT results_eq('SELECT c.relreplident::text FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = ''partman_test'' AND c.relname = ''time_taptest_table_p''||to_char(CURRENT_TIMESTAMP+''6 day''::interval, ''YYYYMMDD'')', ARRAY['i'], 'Check that replica identity was inherited to time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'6 day'::interval, 'YYYYMMDD') );

SELECT results_eq('SELECT c.relreplident::text FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = ''partman_test'' AND c.relname = ''time_taptest_table_p''||to_char(CURRENT_TIMESTAMP+''7 day''::interval, ''YYYYMMDD'')', ARRAY['i'], 'Check that replica identity was inherited to time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'7 day'::interval, 'YYYYMMDD') );

SELECT results_eq('SELECT c.relreplident::text FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = ''partman_test'' AND c.relname = ''time_taptest_table_p''||to_char(CURRENT_TIMESTAMP+''8 day''::interval, ''YYYYMMDD'')', ARRAY['i'], 'Check that replica identity was inherited to time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'8 day'::interval, 'YYYYMMDD') );

-- Insert data outside covered children to check that default table is able to have data removed as part of publication. Also provides
-- another test that default got the replica identity
INSERT INTO partman_test.time_taptest_table (col1, col3) VALUES (generate_series(200,205), CURRENT_TIMESTAMP + '20 days'::interval);
SELECT results_eq('SELECT count(*)::int FROM partman_test.time_taptest_table_default', ARRAY[6], 'Check that data outside existing child scope goes to default');
SELECT partition_data_time('partman_test.time_taptest_table', 20);

UPDATE part_config SET retention = '2 days'::interval, retention_keep_table = true WHERE parent_table = 'partman_test.time_taptest_table';
SELECT run_maintenance();
-- Check for new oldest table
SELECT results_eq('SELECT partition_tablename FROM partman.show_partitions(''partman_test.time_taptest_table'') LIMIT 1', ARRAY['time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'2 days'::interval, 'YYYYMMDD')], 'Check that -2 day old table table is oldest table');
-- Ensure that -4 & -3 day tables still exists
SELECT has_table('partman_test', 'time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'3 days'::interval, 'YYYYMMDD'),
'Check time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'3 days'::interval, 'YYYYMMDD')||' exists');
SELECT has_table('partman_test', 'time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'4 days'::interval, 'YYYYMMDD'),
'Check time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'4 days'::interval, 'YYYYMMDD')||' exists');
-- Ensure that publication is dropped from detached tables
SELECT is_empty('SELECT pubname FROM pg_publication_tables WHERE tablename = ''time_taptest_table_p''||to_char(CURRENT_TIMESTAMP-''3 day''::interval, ''YYYYMMDD'') AND pubname = ''partman_test_publication''', 'Ensure time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'3 day'::interval, 'YYYYMMDD')||' was removed from publication');
SELECT is_empty('SELECT pubname FROM pg_publication_tables WHERE tablename = ''time_taptest_table_p''||to_char(CURRENT_TIMESTAMP-''4 day''::interval, ''YYYYMMDD'') AND pubname = ''partman_test_publication''', 'Ensure time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'4 day'::interval, 'YYYYMMDD')||' was removed from publication');
-- Ensure that publication still exists on -2 day old table
-- Cannot get this test to work right now
--SELECT results_eq('SELECT pubname::text FROM pg_publication_tables WHERE tablename = ''time_taptest_table_p''||to_char(CURRENT_TIMESTAMP-''2 day''::interval, ''YYYYMMDD'') AND pubname = ''partman_test_publication'' LIMIT 1', ARRAY['partman_test_publication'] ,'Ensure time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'2 day'::interval, 'YYYYMMDD')||' is still in publication');


SELECT * FROM finish();
ROLLBACK;
Loading

0 comments on commit 41bc480

Please sign in to comment.