Skip to content

Commit c167161

Browse files
committed
fix: fix list partitioning with bigint
1 parent 2e62516 commit c167161

File tree

6 files changed

+148
-11
lines changed

6 files changed

+148
-11
lines changed

CHANGELOG.md

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -14,11 +14,11 @@ NEW FEATURES
1414
BUG FIXES
1515
---------
1616
- Enforcement of the control column being NOT NULL was not being done as intended. This has been fixed. If you'd like to allow the control column to be NULL, see the new feature flag in 5.2.0
17+
- Fixed handling of bigint data type with LIST partitioning. New partitions were not being created during maintenance and `show_*` functions were not giving expected results. (Github Issue #704)
1718
- Fixed `reapply_constraint_proc()` to work properly when there are no relevant child tables to place additional constraints. In the process reworked the logic to determine the target child tables for both that procedure and the apply_constraints() function. The determining factor is now always the newest child table that contains data (other than the default). Updated documentation to clarify how the optimize_constraint flag works. (Github Issue #694)
1819
- Properly handle partial indexes that are inherited from the template table. (Github Issue #657)
1920
- Move the retention logic for dropping tables later in the maintenance process to help avoid longer running heavy locks on partition sets. (Github Issue #678)
2021

21-
2222
5.1.0
2323
=====
2424
NEW FEATURES

sql/functions/show_partition_info.sql

Lines changed: 4 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -93,7 +93,7 @@ IF v_partstrat = 'r' THEN
9393
AND n.nspname = v_child_schema;
9494
ELSIF v_partstrat = 'l' THEN
9595
SELECT (regexp_match(pg_get_expr(c.relpartbound, c.oid, true)
96-
, $REGEX$FOR VALUES IN \(([^)])\)$REGEX$))[1]::text
96+
, $REGEX$FOR VALUES IN \(([^)]+)\)$REGEX$))[1]::text
9797
INTO v_start_string
9898
FROM pg_catalog.pg_class c
9999
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
@@ -132,10 +132,11 @@ IF v_control_type = 'time' OR (v_control_type = 'id' AND v_epoch <> 'none') THEN
132132
ELSIF v_control_type = 'id' THEN
133133

134134
IF v_exact_control_type IN ('int8', 'int4', 'int2') THEN
135-
child_start_id := trim(BOTH '''' FROM v_start_string)::bigint;
135+
-- Have to do a trim here because of inconsistency in quoting different integer types. Ex: bigint boundary values are quoted but int values are not
136+
child_start_id := trim(BOTH $QUOTE$''$QUOTE$ FROM v_start_string)::bigint;
136137
ELSIF v_exact_control_type = 'numeric' THEN
137138
-- cast to numeric then trunc to get rid of decimal without rounding
138-
child_start_id := trunc(trim(BOTH '''' FROM v_start_string)::numeric)::bigint;
139+
child_start_id := trunc(trim(BOTH $QUOTE$''$QUOTE$ FROM v_start_string)::numeric)::bigint;
139140
END IF;
140141

141142
child_end_id := (child_start_id + v_partition_interval::bigint) - 1;

sql/functions/show_partitions.sql

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -114,13 +114,13 @@ ELSIF v_control_type = 'id' AND v_epoch <> 'none' THEN
114114
ELSIF v_control_type = 'id' THEN
115115

116116
IF v_partition_type = 'range' THEN
117-
-- Have to do a trim here because of inconsistency in quoting different integer types. Ex: bigint boundary values are quoted but int values are not
117+
-- Have to do trims here because of inconsistency in quoting different integer types. Ex: bigint boundary values are quoted but int values are not
118118
v_sql := v_sql || format('
119119
ORDER BY trim( BOTH $QUOTE$''$QUOTE$ from (regexp_match(pg_get_expr(c.relpartbound, c.oid, true), $REGEX$\(([^)]+)\) TO \(([^)]+)\)$REGEX$))[1]::text )::%s %s '
120120
, v_exact_control_type, p_order);
121121
ELSIF v_partition_type = 'list' THEN
122122
v_sql := v_sql || format('
123-
ORDER BY trim((regexp_match(pg_get_expr(c.relpartbound, c.oid, true), $REGEX$FOR VALUES IN \(([^)])\)$REGEX$))[1])::%s %s '
123+
ORDER BY trim( BOTH $QUOTES$''$QUOTES$ from (regexp_match(pg_get_expr(c.relpartbound, c.oid, true), $REGEX$FOR VALUES IN \(([^)]+)\)$REGEX$))[1])::%s %s '
124124
, v_exact_control_type , p_order);
125125
ELSE
126126
RAISE EXCEPTION 'show_partitions: Unsupported partition type found: %', v_partition_type;

test/test-id-1-bigint-list.sql

Lines changed: 134 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,134 @@
1+
-- ########## ID LIST TESTS (increment 1) ##########
2+
-- Additional tests:
3+
-- pre-created template table and passing to create_parent. Should allow indexes to be made for initial children.
4+
-- bigint (to account for difference in int vs bigint in partition expression)
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(61);
13+
CREATE SCHEMA partman_test;
14+
CREATE SCHEMA partman_retention_test;
15+
16+
CREATE TABLE partman_test.id_taptest_table
17+
(col1 bigint
18+
, col2 bigint NOT NULL
19+
, col3 timestamptz DEFAULT now()
20+
, col4 text)
21+
PARTITION BY LIST (col2);
22+
CREATE TABLE partman_test.undo_taptest (LIKE partman_test.id_taptest_table INCLUDING ALL);
23+
-- Template table
24+
CREATE TABLE partman_test.template_id_taptest_table (LIKE partman_test.id_taptest_table);
25+
ALTER TABLE partman_test.template_id_taptest_table ADD PRIMARY KEY (col1);
26+
CREATE INDEX ON partman_test.id_taptest_table (col2);
27+
28+
SELECT create_parent('partman_test.id_taptest_table', 'col2', '1', 'list', p_template_table := 'partman_test.template_id_taptest_table');
29+
UPDATE part_config SET inherit_privileges = TRUE;
30+
SELECT reapply_privileges('partman_test.id_taptest_table');
31+
32+
INSERT INTO partman_test.id_taptest_table (col1, col2, col4) VALUES (generate_series(0,9),0, 'stuff'||generate_series(0,9));
33+
INSERT INTO partman_test.id_taptest_table (col1, col2, col4) VALUES (generate_series(10,19),1, 'stuff'||generate_series(10,19));
34+
INSERT INTO partman_test.id_taptest_table (col1, col2, col4) VALUES (generate_series(20,29),2, 'stuff'||generate_series(20,29));
35+
INSERT INTO partman_test.id_taptest_table (col1, col2, col4) VALUES (generate_series(30,39),3, 'stuff'||generate_series(30,39));
36+
INSERT INTO partman_test.id_taptest_table (col1, col2, col4) VALUES (generate_series(40,49),4, 'stuff'||generate_series(40,49));
37+
38+
SELECT has_table('partman_test', 'id_taptest_table_p0', 'Check id_taptest_table_p0 exists');
39+
SELECT has_table('partman_test', 'id_taptest_table_p1', 'Check id_taptest_table_p1 exists');
40+
SELECT has_table('partman_test', 'id_taptest_table_p2', 'Check id_taptest_table_p2 exists');
41+
SELECT has_table('partman_test', 'id_taptest_table_p3', 'Check id_taptest_table_p3 exists');
42+
SELECT has_table('partman_test', 'id_taptest_table_p4', 'Check id_taptest_table_p4 exists');
43+
SELECT has_table('partman_test', 'id_taptest_table_default', 'Check id_taptest_table_default exists');
44+
SELECT hasnt_table('partman_test', 'id_taptest_table_p5', 'Check id_taptest_table_p5 doesn''t exists yet');
45+
SELECT col_is_pk('partman_test', 'id_taptest_table_p0', ARRAY['col1'], 'Check for primary key in id_taptest_table_p3');
46+
SELECT col_is_pk('partman_test', 'id_taptest_table_p1', ARRAY['col1'], 'Check for primary key in id_taptest_table_p3');
47+
SELECT col_is_pk('partman_test', 'id_taptest_table_p2', ARRAY['col1'], 'Check for primary key in id_taptest_table_p3');
48+
SELECT col_is_pk('partman_test', 'id_taptest_table_p3', ARRAY['col1'], 'Check for primary key in id_taptest_table_p3');
49+
SELECT col_is_pk('partman_test', 'id_taptest_table_p4', ARRAY['col1'], 'Check for primary key in id_taptest_table_p3');
50+
SELECT col_is_pk('partman_test', 'id_taptest_table_default', ARRAY['col1'], 'Check for primary key in id_taptest_table_default');
51+
52+
SELECT is_empty('SELECT * FROM ONLY partman_test.id_taptest_table_default', 'Check that default table has no data');
53+
SELECT results_eq('SELECT count(*)::int FROM partman_test.id_taptest_table', ARRAY[50], 'Check count from parent table');
54+
SELECT results_eq('SELECT count(*)::int FROM partman_test.id_taptest_table_p0', ARRAY[10], 'Check count from id_taptest_table_p0');
55+
56+
SELECT run_maintenance();
57+
INSERT INTO partman_test.id_taptest_table (col1, col2, col4) VALUES (generate_series(50,59),5, 'stuff'||generate_series(50,59));
58+
-- Run again to make new partition based on latest data
59+
SELECT run_maintenance();
60+
61+
SELECT is_empty('SELECT * FROM ONLY partman_test.id_taptest_table', 'Check that parent table has had no data inserted to it');
62+
SELECT results_eq('SELECT count(*)::int FROM partman_test.id_taptest_table_p1', ARRAY[10], 'Check count from id_taptest_table_p1');
63+
SELECT results_eq('SELECT count(*)::int FROM partman_test.id_taptest_table_p2', ARRAY[10], 'Check count from id_taptest_table_p2');
64+
65+
SELECT has_table('partman_test', 'id_taptest_table_p5', 'Check id_taptest_table_p5 exists');
66+
SELECT has_table('partman_test', 'id_taptest_table_p6', 'Check id_taptest_table_p6 exists yet');
67+
SELECT has_table('partman_test', 'id_taptest_table_p7', 'Check id_taptest_table_p6 exists yet');
68+
SELECT has_table('partman_test', 'id_taptest_table_p8', 'Check id_taptest_table_p6 exists yet');
69+
SELECT has_table('partman_test', 'id_taptest_table_p9', 'Check id_taptest_table_p6 exists yet');
70+
SELECT hasnt_table('partman_test', 'id_taptest_table_p10', 'Check id_taptest_table_p10 doesn''t exists yet');
71+
SELECT col_is_pk('partman_test', 'id_taptest_table_p5', ARRAY['col1'], 'Check for primary key in id_taptest_table_p5');
72+
SELECT col_is_pk('partman_test', 'id_taptest_table_p6', ARRAY['col1'], 'Check for primary key in id_taptest_table_p6');
73+
SELECT col_is_pk('partman_test', 'id_taptest_table_p7', ARRAY['col1'], 'Check for primary key in id_taptest_table_p7');
74+
SELECT col_is_pk('partman_test', 'id_taptest_table_p8', ARRAY['col1'], 'Check for primary key in id_taptest_table_p8');
75+
SELECT col_is_pk('partman_test', 'id_taptest_table_p9', ARRAY['col1'], 'Check for primary key in id_taptest_table_p9');
76+
77+
INSERT INTO partman_test.id_taptest_table (col1, col2, col4) VALUES (generate_series(60,69),6, 'stuff'||generate_series(60,69));
78+
79+
SELECT run_maintenance();
80+
81+
SELECT is_empty('SELECT * FROM partman_test.id_taptest_table_default', 'Check that default table has had no data inserted to it');
82+
SELECT results_eq('SELECT count(*)::int FROM partman_test.id_taptest_table', ARRAY[70], 'Check count from id_taptest_table');
83+
SELECT results_eq('SELECT count(*)::int FROM partman_test.id_taptest_table_p5', ARRAY[10], 'Check count from id_taptest_table_p5');
84+
SELECT results_eq('SELECT count(*)::int FROM partman_test.id_taptest_table_p6', ARRAY[10], 'Check count from id_taptest_table_p6');
85+
86+
SELECT has_table('partman_test', 'id_taptest_table_p10', 'Check id_taptest_table_p10 exists');
87+
SELECT hasnt_table('partman_test', 'id_taptest_table_p11', 'Check id_taptest_table_p11 doesn''t exists yet');
88+
SELECT col_is_pk('partman_test', 'id_taptest_table_p10', ARRAY['col1'], 'Check for primary key in id_taptest_table_p10');
89+
90+
INSERT INTO partman_test.id_taptest_table (col1, col2, col4) VALUES (generate_series(200,210),200, 'stuff'||generate_series(200,200));
91+
SELECT results_eq('SELECT count(*)::int FROM ONLY partman_test.id_taptest_table_default', ARRAY[11], 'Check that data outside child scope goes to default');
92+
SELECT run_maintenance();
93+
94+
-- Max value is 6 above (not including default)
95+
SELECT drop_partition_id('partman_test.id_taptest_table', '4', p_keep_table := false);
96+
SELECT hasnt_table('partman_test', 'id_taptest_table_p0', 'Check id_taptest_table_p0 doesn''t exists anymore');
97+
SELECT hasnt_table('partman_test', 'id_taptest_table_p1', 'Check id_taptest_table_p1 doesn''t exists anymore');
98+
SELECT has_table('partman_test', 'id_taptest_table_p2', 'Check id_taptest_table_p2 still exists');
99+
100+
UPDATE part_config SET retention = '3', retention_keep_table = 'false' WHERE parent_table = 'partman_test.id_taptest_table';
101+
SELECT drop_partition_id('partman_test.id_taptest_table');
102+
SELECT hasnt_table('partman_test', 'id_taptest_table_p2', 'Check id_taptest_table_p2 doesn''t exists anymore');
103+
SELECT has_table('partman_test', 'id_taptest_table_p3', 'Check id_taptest_table_p3 still exists');
104+
105+
-- Undo will remove default first if it exists and has data. Don't keep default
106+
SELECT undo_partition('partman_test.id_taptest_table', 'partman_test.undo_taptest', p_keep_table := false);
107+
SELECT hasnt_table('partman_test', 'id_taptest_table_default', 'Check id_taptest_table_default does not exist');
108+
109+
-- Test undo removing one more table but keeping that data
110+
SELECT undo_partition('partman_test.id_taptest_table', 'partman_test.undo_taptest', p_keep_table := false);
111+
SELECT hasnt_table('partman_test', 'id_taptest_table_p3', 'Check id_taptest_table_p3 does not exist');
112+
113+
-- Test keeping the rest of the tables
114+
SELECT undo_partition('partman_test.id_taptest_table', 'partman_test.undo_taptest', 10);
115+
SELECT results_eq('SELECT count(*)::int FROM ONLY partman_test.undo_taptest', ARRAY[51], 'Check count from undo table after undo');
116+
SELECT has_table('partman_test', 'id_taptest_table_p4', 'Check id_taptest_table_p4 still exists');
117+
SELECT is_empty('SELECT * FROM partman_test.id_taptest_table_p4', 'Check child table had its data removed id_taptest_table_p4');
118+
SELECT has_table('partman_test', 'id_taptest_table_p5', 'Check id_taptest_table_p5 still exists');
119+
SELECT is_empty('SELECT * FROM partman_test.id_taptest_table_p5', 'Check child table had its data removed id_taptest_table_p5');
120+
SELECT has_table('partman_test', 'id_taptest_table_p6', 'Check id_taptest_table_p6 still exists');
121+
SELECT is_empty('SELECT * FROM partman_test.id_taptest_table_p6', 'Check child table had its data removed id_taptest_table_p6');
122+
SELECT has_table('partman_test', 'id_taptest_table_p7', 'Check id_taptest_table_p7 still exists');
123+
SELECT is_empty('SELECT * FROM partman_test.id_taptest_table_p7', 'Check child table had its data removed id_taptest_table_p7');
124+
SELECT has_table('partman_test', 'id_taptest_table_p8', 'Check id_taptest_table_p8 still exists');
125+
SELECT is_empty('SELECT * FROM partman_test.id_taptest_table_p8', 'Check child table had its data removed id_taptest_table_p8');
126+
SELECT has_table('partman_test', 'id_taptest_table_p9', 'Check id_taptest_table_p9 still exists');
127+
SELECT is_empty('SELECT * FROM partman_test.id_taptest_table_p9', 'Check child table had its data removed id_taptest_table_p9');
128+
SELECT has_table('partman_test', 'id_taptest_table_p10', 'Check id_taptest_table_p10 still exists');
129+
SELECT is_empty('SELECT * FROM partman_test.id_taptest_table_p10', 'Check child table had its data removed id_taptest_table_p10');
130+
131+
SELECT hasnt_table('partman_test', 'template_id_taptest_table', 'Check that template table was dropped');
132+
133+
SELECT * FROM finish();
134+
ROLLBACK;

test/test-id-1-list.sql renamed to test/test-id-1-int-list.sql

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1,6 +1,7 @@
11
-- ########## ID LIST TESTS (increment 1) ##########
22
-- Additional tests:
33
-- pre-created template table and passing to create_parent. Should allow indexes to be made for initial children.
4+
-- int (to account for difference in int vs bigint in partition expression)
45

56
\set ON_ERROR_ROLLBACK 1
67
\set ON_ERROR_STOP true

updates/pg_partman--5.1.0--5.2.0.sql

Lines changed: 6 additions & 5 deletions
Original file line numberDiff line numberDiff line change
@@ -411,7 +411,7 @@ IF v_partstrat = 'r' THEN
411411
AND n.nspname = v_child_schema;
412412
ELSIF v_partstrat = 'l' THEN
413413
SELECT (regexp_match(pg_get_expr(c.relpartbound, c.oid, true)
414-
, $REGEX$FOR VALUES IN \(([^)])\)$REGEX$))[1]::text
414+
, $REGEX$FOR VALUES IN \(([^)]+)\)$REGEX$))[1]::text
415415
INTO v_start_string
416416
FROM pg_catalog.pg_class c
417417
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
@@ -450,10 +450,11 @@ IF v_control_type = 'time' OR (v_control_type = 'id' AND v_epoch <> 'none') THEN
450450
ELSIF v_control_type = 'id' THEN
451451

452452
IF v_exact_control_type IN ('int8', 'int4', 'int2') THEN
453-
child_start_id := trim(BOTH '''' FROM v_start_string)::bigint;
453+
-- Have to do a trim here because of inconsistency in quoting different integer types. Ex: bigint boundary values are quoted but int values are not
454+
child_start_id := trim(BOTH $QUOTE$''$QUOTE$ FROM v_start_string)::bigint;
454455
ELSIF v_exact_control_type = 'numeric' THEN
455456
-- cast to numeric then trunc to get rid of decimal without rounding
456-
child_start_id := trunc(trim(BOTH '''' FROM v_start_string)::numeric)::bigint;
457+
child_start_id := trunc(trim(BOTH $QUOTE$''$QUOTE$ FROM v_start_string)::numeric)::bigint;
457458
END IF;
458459

459460
child_end_id := (child_start_id + v_partition_interval::bigint) - 1;
@@ -584,13 +585,13 @@ ELSIF v_control_type = 'id' AND v_epoch <> 'none' THEN
584585
ELSIF v_control_type = 'id' THEN
585586

586587
IF v_partition_type = 'range' THEN
587-
-- Have to do a trim here because of inconsistency in quoting different integer types. Ex: bigint boundary values are quoted but int values are not
588+
-- Have to do trims here because of inconsistency in quoting different integer types. Ex: bigint boundary values are quoted but int values are not
588589
v_sql := v_sql || format('
589590
ORDER BY trim( BOTH $QUOTE$''$QUOTE$ from (regexp_match(pg_get_expr(c.relpartbound, c.oid, true), $REGEX$\(([^)]+)\) TO \(([^)]+)\)$REGEX$))[1]::text )::%s %s '
590591
, v_exact_control_type, p_order);
591592
ELSIF v_partition_type = 'list' THEN
592593
v_sql := v_sql || format('
593-
ORDER BY trim((regexp_match(pg_get_expr(c.relpartbound, c.oid, true), $REGEX$FOR VALUES IN \(([^)])\)$REGEX$))[1])::%s %s '
594+
ORDER BY trim( BOTH $QUOTES$''$QUOTES$ from (regexp_match(pg_get_expr(c.relpartbound, c.oid, true), $REGEX$FOR VALUES IN \(([^)]+)\)$REGEX$))[1])::%s %s '
594595
, v_exact_control_type , p_order);
595596
ELSE
596597
RAISE EXCEPTION 'show_partitions: Unsupported partition type found: %', v_partition_type;

0 commit comments

Comments
 (0)