Skip to content

Commit 0737c24

Browse files
author
psmaron
committed
v4.2.1 Fix bug in partition_data_time causing never-ending loop while calculating partition range
1 parent de0bf4e commit 0737c24

File tree

5 files changed

+320
-5
lines changed

5 files changed

+320
-5
lines changed

CHANGELOG.txt

Lines changed: 3 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1,3 +1,6 @@
1+
4.2.1
2+
-- Fix bug in partition_data_time causing never-ending loop while calculating partition range for natively partitioned tables. Github issue #273
3+
14
4.2.0
25
-- Preliminary compatability with PostgreSQL 12.
36

META.json

Lines changed: 3 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -1,7 +1,7 @@
11
{
22
"name": "pg_partman",
33
"abstract": "Extension to manage partitioned tables by time or ID",
4-
"version": "4.2.0",
4+
"version": "4.2.1",
55
"maintainer": [
66
"Keith Fiske <[email protected]>"
77
],
@@ -20,9 +20,9 @@
2020
},
2121
"provides": {
2222
"pg_partman": {
23-
"file": "sql/pg_partman--4.2.0.sql",
23+
"file": "sql/pg_partman--4.2.1.sql",
2424
"docfile": "doc/pg_partman.md",
25-
"version": "4.2.0",
25+
"version": "4.2.1",
2626
"abstract": "Extension to manage partitioned tables by time or ID"
2727
}
2828
},

pg_partman.control

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1,3 +1,3 @@
1-
default_version = '4.2.0'
1+
default_version = '4.2.1'
22
comment = 'Extension to manage partitioned tables by time or ID'
33
relocatable = false

sql/functions/partition_data_time.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -184,7 +184,7 @@ FOR i IN 1..p_batch_count LOOP
184184
EXIT;
185185
ELSE
186186
BEGIN
187-
IF v_start_control > v_max_partition_timestamp THEN
187+
IF v_start_control >= v_max_partition_timestamp THEN
188188
-- Keep going forward in time, checking if child partition time interval encompasses the current v_start_control value
189189
v_min_partition_timestamp := v_max_partition_timestamp;
190190
v_max_partition_timestamp := v_max_partition_timestamp + v_partition_interval;
Lines changed: 312 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,312 @@
1+
-- Fix bug causing never-ending loop while calculating partition range for natively partitioned tables. Github issue #273
2+
3+
CREATE FUNCTION @[email protected]_data_time(
4+
p_parent_table text
5+
, p_batch_count int DEFAULT 1
6+
, p_batch_interval interval DEFAULT NULL
7+
, p_lock_wait numeric DEFAULT 0
8+
, p_order text DEFAULT 'ASC'
9+
, p_analyze boolean DEFAULT true
10+
, p_source_table text DEFAULT NULL)
11+
RETURNS bigint
12+
LANGUAGE plpgsql
13+
AS $$
14+
DECLARE
15+
16+
v_control text;
17+
v_control_type text;
18+
v_datetime_string text;
19+
v_current_partition_name text;
20+
v_default_exists boolean;
21+
v_default_schemaname text;
22+
v_default_tablename text;
23+
v_epoch text;
24+
v_last_partition text;
25+
v_lock_iter int := 1;
26+
v_lock_obtained boolean := FALSE;
27+
v_max_partition_timestamp timestamptz;
28+
v_min_partition_timestamp timestamptz;
29+
v_new_search_path text := '@extschema@,pg_temp';
30+
v_old_search_path text;
31+
v_parent_tablename text;
32+
v_parent_tablename_real text;
33+
v_partition_expression text;
34+
v_partition_interval interval;
35+
v_partition_suffix text;
36+
v_partition_timestamp timestamptz[];
37+
v_partition_type text;
38+
v_source_schemaname text;
39+
v_source_tablename text;
40+
v_rowcount bigint;
41+
v_sql text;
42+
v_start_control timestamptz;
43+
v_total_rows bigint := 0;
44+
45+
BEGIN
46+
/*
47+
* Populate the child table(s) of a time-based partition set with old data from the original parent
48+
*/
49+
50+
SELECT partition_type
51+
, partition_interval::interval
52+
, control
53+
, datetime_string
54+
, epoch
55+
INTO v_partition_type
56+
, v_partition_interval
57+
, v_control
58+
, v_datetime_string
59+
, v_epoch
60+
FROM @[email protected]_config
61+
WHERE parent_table = p_parent_table;
62+
IF NOT FOUND THEN
63+
RAISE EXCEPTION 'ERROR: No entry in part_config found for given table: %', p_parent_table;
64+
END IF;
65+
66+
SELECT schemaname, tablename INTO v_source_schemaname, v_source_tablename
67+
FROM pg_catalog.pg_tables
68+
WHERE schemaname = split_part(p_parent_table, '.', 1)::name
69+
AND tablename = split_part(p_parent_table, '.', 2)::name;
70+
71+
-- Preserve real parent tablename for use below
72+
v_parent_tablename := v_source_tablename;
73+
74+
SELECT general_type INTO v_control_type FROM @[email protected]_control_type(v_source_schemaname, v_source_tablename, v_control);
75+
76+
IF v_control_type <> 'time' THEN
77+
IF (v_control_type = 'id' AND v_epoch = 'none') OR v_control_type <> 'id' THEN
78+
RAISE EXCEPTION 'Cannot run on partition set without time based control column or epoch flag set with an id column. Found control: %, epoch: %', v_control_type, v_epoch;
79+
END IF;
80+
END IF;
81+
82+
-- Replace the parent variables with the source variables if using source table for child table data
83+
IF p_source_table IS NOT NULL THEN
84+
-- Set source table to user given source table instead of parent table
85+
v_source_schemaname := NULL;
86+
v_source_tablename := NULL;
87+
88+
SELECT schemaname, tablename INTO v_source_schemaname, v_source_tablename
89+
FROM pg_catalog.pg_tables
90+
WHERE schemaname = split_part(p_source_table, '.', 1)::name
91+
AND tablename = split_part(p_source_table, '.', 2)::name;
92+
93+
IF v_source_tablename IS NULL THEN
94+
RAISE EXCEPTION 'Given source table does not exist in system catalogs: %', p_source_table;
95+
END IF;
96+
97+
98+
ELSIF v_partition_type = 'native' AND current_setting('server_version_num')::int >= 110000 THEN
99+
100+
IF p_batch_interval IS NOT NULL AND p_batch_interval != v_partition_interval THEN
101+
-- This is true because all data for a given child table must be moved out of the default partition before the child table can be created.
102+
-- So cannot create the child table when only some of the data has been moved out of the default partition.
103+
RAISE EXCEPTION 'Custom intervals are not allowed when moving data out of the DEFAULT partition in a native set. Please leave p_interval/p_batch_interval parameters unset or NULL to allow use of partition set''s default partitioning interval.';
104+
END IF;
105+
-- Set source table to default table if PG11+, p_source_table is not set, and it exists
106+
-- Otherwise just return with a DEBUG that no data source exists
107+
v_sql := format('SELECT n.nspname::text, c.relname::text FROM
108+
pg_catalog.pg_inherits h
109+
JOIN pg_catalog.pg_class c ON c.oid = h.inhrelid
110+
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
111+
WHERE h.inhparent = ''%I.%I''::regclass
112+
AND pg_get_expr(relpartbound, c.oid) = ''DEFAULT'''
113+
, v_source_schemaname
114+
, v_source_tablename);
115+
116+
EXECUTE v_sql INTO v_default_schemaname, v_default_tablename;
117+
IF v_default_tablename IS NOT NULL THEN
118+
v_source_schemaname := v_default_schemaname;
119+
v_source_tablename := v_default_tablename;
120+
121+
v_default_exists := true;
122+
EXECUTE format ('CREATE TEMP TABLE IF NOT EXISTS partman_temp_data_storage (LIKE %I.%I INCLUDING INDEXES)', v_source_schemaname, v_source_tablename);
123+
ELSE
124+
RAISE DEBUG 'No default table found when partition_data_id() was called';
125+
RETURN v_total_rows;
126+
END IF;
127+
END IF;
128+
129+
SELECT current_setting('search_path') INTO v_old_search_path;
130+
EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_new_search_path, 'false');
131+
132+
IF p_batch_interval IS NULL OR p_batch_interval > v_partition_interval THEN
133+
p_batch_interval := v_partition_interval;
134+
END IF;
135+
136+
SELECT partition_tablename INTO v_last_partition FROM @[email protected]_partitions(p_parent_table, 'DESC') LIMIT 1;
137+
138+
v_partition_expression := CASE
139+
WHEN v_epoch = 'seconds' THEN format('to_timestamp(%I)', v_control)
140+
WHEN v_epoch = 'milliseconds' THEN format('to_timestamp((%I/1000)::float)', v_control)
141+
ELSE format('%I', v_control)
142+
END;
143+
144+
FOR i IN 1..p_batch_count LOOP
145+
146+
IF p_order = 'ASC' THEN
147+
EXECUTE format('SELECT min(%s) FROM ONLY %I.%I', v_partition_expression, v_source_schemaname, v_source_tablename) INTO v_start_control;
148+
ELSIF p_order = 'DESC' THEN
149+
EXECUTE format('SELECT max(%s) FROM ONLY %I.%I', v_partition_expression, v_source_schemaname, v_source_tablename) INTO v_start_control;
150+
ELSE
151+
RAISE EXCEPTION 'Invalid value for p_order. Must be ASC or DESC';
152+
END IF;
153+
154+
IF v_start_control IS NULL THEN
155+
EXIT;
156+
END IF;
157+
158+
IF v_partition_type = 'partman' THEN
159+
CASE
160+
WHEN v_partition_interval = '15 mins' THEN
161+
v_min_partition_timestamp := date_trunc('hour', v_start_control) +
162+
'15min'::interval * floor(date_part('minute', v_start_control) / 15.0);
163+
WHEN v_partition_interval = '30 mins' THEN
164+
v_min_partition_timestamp := date_trunc('hour', v_start_control) +
165+
'30min'::interval * floor(date_part('minute', v_start_control) / 30.0);
166+
WHEN v_partition_interval = '1 hour' THEN
167+
v_min_partition_timestamp := date_trunc('hour', v_start_control);
168+
WHEN v_partition_interval = '1 day' THEN
169+
v_min_partition_timestamp := date_trunc('day', v_start_control);
170+
WHEN v_partition_interval = '1 week' THEN
171+
v_min_partition_timestamp := date_trunc('week', v_start_control);
172+
WHEN v_partition_interval = '1 month' THEN
173+
v_min_partition_timestamp := date_trunc('month', v_start_control);
174+
WHEN v_partition_interval = '3 months' THEN
175+
v_min_partition_timestamp := date_trunc('quarter', v_start_control);
176+
WHEN v_partition_interval = '1 year' THEN
177+
v_min_partition_timestamp := date_trunc('year', v_start_control);
178+
END CASE;
179+
ELSIF v_partition_type IN ('time-custom', 'native') THEN
180+
SELECT child_start_time INTO v_min_partition_timestamp FROM @[email protected]_partition_info(v_source_schemaname||'.'||v_last_partition
181+
, v_partition_interval::text
182+
, p_parent_table);
183+
v_max_partition_timestamp := v_min_partition_timestamp + v_partition_interval;
184+
LOOP
185+
IF v_start_control >= v_min_partition_timestamp AND v_start_control < v_max_partition_timestamp THEN
186+
EXIT;
187+
ELSE
188+
BEGIN
189+
IF v_start_control >= v_max_partition_timestamp THEN
190+
-- Keep going forward in time, checking if child partition time interval encompasses the current v_start_control value
191+
v_min_partition_timestamp := v_max_partition_timestamp;
192+
v_max_partition_timestamp := v_max_partition_timestamp + v_partition_interval;
193+
194+
ELSE
195+
-- Keep going backwards in time, checking if child partition time interval encompasses the current v_start_control value
196+
v_max_partition_timestamp := v_min_partition_timestamp;
197+
v_min_partition_timestamp := v_min_partition_timestamp - v_partition_interval;
198+
END IF;
199+
EXCEPTION WHEN datetime_field_overflow THEN
200+
RAISE EXCEPTION 'Attempted partition time interval is outside PostgreSQL''s supported time range.
201+
Unable to create partition with interval before timestamp % ', v_min_partition_timestamp;
202+
END;
203+
END IF;
204+
END LOOP;
205+
206+
END IF;
207+
208+
v_partition_timestamp := ARRAY[v_min_partition_timestamp];
209+
IF p_order = 'ASC' THEN
210+
-- Ensure batch interval given as parameter doesn't cause maximum to overflow the current partition maximum
211+
IF (v_start_control + p_batch_interval) >= (v_min_partition_timestamp + v_partition_interval) THEN
212+
v_max_partition_timestamp := v_min_partition_timestamp + v_partition_interval;
213+
ELSE
214+
v_max_partition_timestamp := v_start_control + p_batch_interval;
215+
END IF;
216+
ELSIF p_order = 'DESC' THEN
217+
-- Must be greater than max value still in parent table since query below grabs < max
218+
v_max_partition_timestamp := v_min_partition_timestamp + v_partition_interval;
219+
-- Ensure batch interval given as parameter doesn't cause minimum to underflow current partition minimum
220+
IF (v_start_control - p_batch_interval) >= v_min_partition_timestamp THEN
221+
v_min_partition_timestamp = v_start_control - p_batch_interval;
222+
END IF;
223+
ELSE
224+
RAISE EXCEPTION 'Invalid value for p_order. Must be ASC or DESC';
225+
END IF;
226+
227+
-- do some locking with timeout, if required
228+
IF p_lock_wait > 0 THEN
229+
v_lock_iter := 0;
230+
WHILE v_lock_iter <= 5 LOOP
231+
v_lock_iter := v_lock_iter + 1;
232+
BEGIN
233+
EXECUTE format('SELECT * FROM ONLY %I.%I WHERE %s >= %L AND %3$s < %5$L FOR UPDATE NOWAIT'
234+
, v_source_schemaname
235+
, v_source_tablename
236+
, v_partition_expression
237+
, v_min_partition_timestamp
238+
, v_max_partition_timestamp);
239+
v_lock_obtained := TRUE;
240+
EXCEPTION
241+
WHEN lock_not_available THEN
242+
PERFORM pg_sleep( p_lock_wait / 5.0 );
243+
CONTINUE;
244+
END;
245+
EXIT WHEN v_lock_obtained;
246+
END LOOP;
247+
IF NOT v_lock_obtained THEN
248+
RETURN -1;
249+
END IF;
250+
END IF;
251+
252+
-- This suffix generation code is in create_partition_time() as well
253+
v_partition_suffix := to_char(v_min_partition_timestamp, v_datetime_string);
254+
v_current_partition_name := @[email protected]_name_length(v_parent_tablename, v_partition_suffix, TRUE);
255+
256+
IF v_default_exists THEN
257+
-- Child tables cannot be created in native partitioning if data that belongs to it exists in the default
258+
-- Have to move data out to temporary location, create child table, then move it back
259+
260+
-- Temp table created above to avoid excessive temp creation in loop
261+
EXECUTE format('WITH partition_data AS (
262+
DELETE FROM %1$I.%2$I WHERE %3$I >= %4$L AND %3$I < %5$L RETURNING *)
263+
INSERT INTO partman_temp_data_storage SELECT * FROM partition_data'
264+
, v_source_schemaname
265+
, v_source_tablename
266+
, v_control
267+
, v_min_partition_timestamp
268+
, v_max_partition_timestamp);
269+
270+
PERFORM @[email protected]_partition_time(p_parent_table, v_partition_timestamp, p_analyze);
271+
272+
EXECUTE format('WITH partition_data AS (
273+
DELETE FROM partman_temp_data_storage RETURNING *)
274+
INSERT INTO %I.%I SELECT * FROM partition_data'
275+
, v_source_schemaname
276+
, v_current_partition_name);
277+
278+
ELSE
279+
280+
PERFORM @[email protected]_partition_time(p_parent_table, v_partition_timestamp, p_analyze);
281+
282+
EXECUTE format('WITH partition_data AS (
283+
DELETE FROM ONLY %I.%I WHERE %s >= %L AND %3$s < %5$L RETURNING *)
284+
INSERT INTO %I.%I SELECT * FROM partition_data'
285+
, v_source_schemaname
286+
, v_source_tablename
287+
, v_partition_expression
288+
, v_min_partition_timestamp
289+
, v_max_partition_timestamp
290+
, v_source_schemaname
291+
, v_current_partition_name);
292+
END IF;
293+
294+
GET DIAGNOSTICS v_rowcount = ROW_COUNT;
295+
v_total_rows := v_total_rows + v_rowcount;
296+
IF v_rowcount = 0 THEN
297+
EXIT;
298+
END IF;
299+
300+
END LOOP;
301+
302+
IF v_partition_type IN ('partman', 'time-custom') THEN
303+
PERFORM @[email protected]_function_time(p_parent_table);
304+
END IF;
305+
306+
EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_old_search_path, 'false');
307+
308+
RETURN v_total_rows;
309+
310+
END
311+
$$;
312+

0 commit comments

Comments
 (0)