Skip to content

Commit 41bc480

Browse files
committed
fix: allow replica identity using index to work with non-search-path schemas. add unit test
1 parent 2052caf commit 41bc480

4 files changed

+151
-24
lines changed

sql/functions/inherit_replica_identity.sql

+16-11
Original file line numberDiff line numberDiff line change
@@ -7,15 +7,19 @@ v_child_partition_index text;
77
v_child_partition_oid oid;
88
v_parent_oid oid;
99
v_parent_replident char;
10-
v_parent_replident_index name;
10+
v_parent_replident_oid oid;
1111
v_replident_string text;
1212
v_sql text;
1313

1414
BEGIN
1515

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

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

3034
IF v_parent_replident = 'i' THEN
3135

32-
SELECT c.relname
33-
INTO v_parent_replident_index
36+
SELECT c.oid
37+
INTO v_parent_replident_oid
3438
FROM pg_catalog.pg_class c
3539
JOIN pg_catalog.pg_index i ON i.indexrelid = c.oid
3640
WHERE i.indrelid = v_parent_oid
@@ -43,18 +47,19 @@ IF v_parent_replident = 'i' THEN
4347
WHERE n.nspname = p_parent_schemaname
4448
AND c.relname = p_child_tablename;
4549

46-
SELECT partition_index.indexrelid::regclass::text
50+
SELECT partition_index_name.relname
4751
INTO v_child_partition_index
48-
FROM pg_index parent_index -- parent index
49-
INNER JOIN pg_inherits index_inheritance ON (index_inheritance.inhparent=parent_index.indexrelid) -- parent partition index
50-
INNER JOIN pg_index partition_index ON (index_inheritance.inhrelid=partition_index.indexrelid) -- connection between parent and partition indexes
51-
INNER JOIN pg_class partition_table ON (partition_table.oid=partition_index.indrelid) -- connection between child table and child index
52+
FROM pg_index parent_index
53+
INNER JOIN pg_catalog.pg_inherits index_inheritance ON (index_inheritance.inhparent=parent_index.indexrelid) -- parent index inheritance
54+
INNER JOIN pg_catalog.pg_index partition_index ON (index_inheritance.inhrelid=partition_index.indexrelid) -- connection between parent index and child index
55+
INNER JOIN pg_catalog.pg_class partition_index_name ON (partition_index.indexrelid=partition_index_name.oid) -- get child index name
56+
INNER JOIN pg_catalog.pg_class partition_table ON (partition_table.oid=partition_index.indrelid) -- connection between child table and child index
5257
WHERE partition_table.oid=v_child_partition_oid -- child partition table
53-
AND parent_index.indexrelid=v_parent_replident_index::regclass; -- parent partition index
58+
AND parent_index.indexrelid=v_parent_replident_oid; -- parent partition index
5459

5560
END IF;
5661

57-
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;
62+
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;
5863

5964
IF v_parent_replident != 'd' THEN
6065
CASE v_parent_replident

test/test-time-replica-identity.sql test/test-time-replica-identity-full.sql

+1-1
Original file line numberDiff line numberDiff line change
@@ -1,6 +1,6 @@
11
-- ########## TIME DAILY TESTS ##########
22
-- Other tests:
3-
-- Test that replica identity is inherited
3+
-- Test that replica identity FULL is inherited
44
-- Ensure partition_data_proc can move data out of default when its in publication
55

66
\set ON_ERROR_ROLLBACK 1
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,118 @@
1+
-- ########## TIME DAILY TESTS ##########
2+
-- Other tests:
3+
-- Test that replica identity USING INDEX is inherited. Note this only works with indexes that actually exist on the parent
4+
-- Ensure partition_data_proc can move data out of default when its in publication
5+
6+
\set ON_ERROR_ROLLBACK 1
7+
\set ON_ERROR_STOP true
8+
9+
BEGIN;
10+
SELECT set_config('search_path','partman, public',false);
11+
12+
SELECT plan(34);
13+
14+
CREATE SCHEMA partman_test;
15+
16+
CREATE TABLE partman_test.time_taptest_table
17+
(col1 int NOT NULL
18+
, col2 text default 'stuff'
19+
, col3 timestamptz NOT NULL DEFAULT now())
20+
PARTITION BY RANGE (col3);
21+
CREATE UNIQUE INDEX time_taptest_table_unq ON partman_test.time_taptest_table (col1, col3);
22+
ALTER TABLE partman_test.time_taptest_table REPLICA IDENTITY USING INDEX time_taptest_table_unq;
23+
24+
-- Create publication before child tables to check it was inherited
25+
CREATE PUBLICATION partman_test_publication FOR TABLE partman_test.time_taptest_table;
26+
27+
SELECT create_parent('partman_test.time_taptest_table', 'col3', '1 day');
28+
29+
INSERT INTO partman_test.time_taptest_table (col1, col3) VALUES (generate_series(1,10), CURRENT_TIMESTAMP);
30+
31+
SELECT is_partitioned('partman_test', 'time_taptest_table', 'Check that time_taptest_table is natively partitioned');
32+
SELECT has_table('partman', 'template_partman_test_time_taptest_table', 'Check that default template table was created');
33+
34+
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');
35+
SELECT has_table('partman_test', 'time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYYMMDD'),
36+
'Check time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYYMMDD')||' exists');
37+
SELECT has_table('partman_test', 'time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYYMMDD'),
38+
'Check time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYYMMDD')||' exists');
39+
SELECT has_table('partman_test', 'time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYYMMDD'),
40+
'Check time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYYMMDD')||' exists');
41+
SELECT has_table('partman_test', 'time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYYMMDD'),
42+
'Check time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYYMMDD')||' exists');
43+
SELECT hasnt_table('partman_test', 'time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYYMMDD'),
44+
'Check time_taptest_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYYMMDD')||' does not exist');
45+
SELECT has_table('partman_test', 'time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'1 day'::interval, 'YYYYMMDD'),
46+
'Check time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'1 day'::interval, 'YYYYMMDD')||' exists');
47+
SELECT has_table('partman_test', 'time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'2 days'::interval, 'YYYYMMDD'),
48+
'Check time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'2 days'::interval, 'YYYYMMDD')||' exists');
49+
SELECT has_table('partman_test', 'time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'3 days'::interval, 'YYYYMMDD'),
50+
'Check time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'3 days'::interval, 'YYYYMMDD')||' exists');
51+
SELECT has_table('partman_test', 'time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'4 days'::interval, 'YYYYMMDD'),
52+
'Check time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'4 days'::interval, 'YYYYMMDD')||' exists');
53+
SELECT hasnt_table('partman_test', 'time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'5 days'::interval, 'YYYYMMDD'),
54+
'Check time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'5 days'::interval, 'YYYYMMDD')||' does not exist');
55+
56+
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');
57+
58+
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' );
59+
60+
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') );
61+
62+
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') );
63+
64+
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') );
65+
66+
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') );
67+
68+
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') );
69+
70+
71+
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') );
72+
73+
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') );
74+
75+
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') );
76+
77+
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') );
78+
79+
INSERT INTO partman_test.time_taptest_table (col1, col3) VALUES (generate_series(11,20), CURRENT_TIMESTAMP + '1 day'::interval);
80+
INSERT INTO partman_test.time_taptest_table (col1, col3) VALUES (generate_series(21,25), CURRENT_TIMESTAMP + '2 days'::interval);
81+
INSERT INTO partman_test.time_taptest_table (col1, col3) VALUES (generate_series(26,30), CURRENT_TIMESTAMP + '3 days'::interval);
82+
INSERT INTO partman_test.time_taptest_table (col1, col3) VALUES (generate_series(31,37), CURRENT_TIMESTAMP + '4 days'::interval);
83+
84+
SELECT run_maintenance();
85+
86+
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') );
87+
88+
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') );
89+
90+
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') );
91+
92+
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') );
93+
94+
-- Insert data outside covered children to check that default table is able to have data removed as part of publication. Also provides
95+
-- another test that default got the replica identity
96+
INSERT INTO partman_test.time_taptest_table (col1, col3) VALUES (generate_series(200,205), CURRENT_TIMESTAMP + '20 days'::interval);
97+
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');
98+
SELECT partition_data_time('partman_test.time_taptest_table', 20);
99+
100+
UPDATE part_config SET retention = '2 days'::interval, retention_keep_table = true WHERE parent_table = 'partman_test.time_taptest_table';
101+
SELECT run_maintenance();
102+
-- Check for new oldest table
103+
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');
104+
-- Ensure that -4 & -3 day tables still exists
105+
SELECT has_table('partman_test', 'time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'3 days'::interval, 'YYYYMMDD'),
106+
'Check time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'3 days'::interval, 'YYYYMMDD')||' exists');
107+
SELECT has_table('partman_test', 'time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'4 days'::interval, 'YYYYMMDD'),
108+
'Check time_taptest_table_p'||to_char(CURRENT_TIMESTAMP-'4 days'::interval, 'YYYYMMDD')||' exists');
109+
-- Ensure that publication is dropped from detached tables
110+
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');
111+
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');
112+
-- Ensure that publication still exists on -2 day old table
113+
-- Cannot get this test to work right now
114+
--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');
115+
116+
117+
SELECT * FROM finish();
118+
ROLLBACK;

0 commit comments

Comments
 (0)