Add a alter_old_partitions_set_access_method UDF

pull/4504/head
Marco Slot 2021-01-13 16:29:59 +01:00
parent bb089c4344
commit b840e97cd6
10 changed files with 245 additions and 4 deletions

View File

@ -32,6 +32,7 @@ DROP FUNCTION IF EXISTS pg_catalog.citus_total_relation_size(regclass);
#include "udfs/time_partition_range/10.0-1.sql"
#include "udfs/time_partitions/10.0-1.sql"
#include "udfs/alter_old_partitions_set_access_method/10.0-1.sql"
ALTER FUNCTION pg_catalog.master_conninfo_cache_invalidate()
RENAME TO citus_conninfo_cache_invalidate;

View File

@ -53,6 +53,7 @@ RENAME TO master_drop_all_shards;
DROP VIEW pg_catalog.time_partitions;
DROP FUNCTION pg_catalog.time_partition_range(regclass);
DROP PROCEDURE pg_catalog.alter_old_partitions_set_access_method(regclass,timestamptz,name);
DROP FUNCTION pg_catalog.citus_set_coordinator_host(text,int,noderole,name);
DROP FUNCTION pg_catalog.worker_change_sequence_dependency(regclass, regclass, regclass);

View File

@ -0,0 +1,42 @@
CREATE OR REPLACE PROCEDURE pg_catalog.alter_old_partitions_set_access_method(
parent_table_name regclass,
older_than timestamptz,
new_access_method name)
LANGUAGE plpgsql
AS $$
DECLARE
r record;
BEGIN
/* first check whether we can convert all the to_value's to timestamptz */
BEGIN
PERFORM
FROM pg_catalog.time_partitions
WHERE parent_table = parent_table_name
AND to_value IS NOT NULL
AND to_value::timestamptz <= older_than
AND access_method <> new_access_method;
EXCEPTION WHEN invalid_datetime_format THEN
RAISE 'partition column of % cannot be cast to a timestamptz', parent_table_name;
END;
/* now convert the partitions in separate transactions */
FOR r IN
SELECT partition, from_value, to_value
FROM pg_catalog.time_partitions
WHERE parent_table = parent_table_name
AND to_value IS NOT NULL
AND to_value::timestamptz <= older_than
AND access_method <> new_access_method
ORDER BY to_value::timestamptz
LOOP
RAISE NOTICE 'converting % with start time % and end time %', r.partition, r.from_value, r.to_value;
PERFORM pg_catalog.alter_table_set_access_method(r.partition, new_access_method);
COMMIT;
END LOOP;
END;
$$;
COMMENT ON PROCEDURE pg_catalog.alter_old_partitions_set_access_method(
parent_table_name regclass,
older_than timestamptz,
new_access_method name)
IS 'convert old partitions of a time-partitioned table to a new access method';

View File

@ -0,0 +1,42 @@
CREATE OR REPLACE PROCEDURE pg_catalog.alter_old_partitions_set_access_method(
parent_table_name regclass,
older_than timestamptz,
new_access_method name)
LANGUAGE plpgsql
AS $$
DECLARE
r record;
BEGIN
/* first check whether we can convert all the to_value's to timestamptz */
BEGIN
PERFORM
FROM pg_catalog.time_partitions
WHERE parent_table = parent_table_name
AND to_value IS NOT NULL
AND to_value::timestamptz <= older_than
AND access_method <> new_access_method;
EXCEPTION WHEN invalid_datetime_format THEN
RAISE 'partition column of % cannot be cast to a timestamptz', parent_table_name;
END;
/* now convert the partitions in separate transactions */
FOR r IN
SELECT partition, from_value, to_value
FROM pg_catalog.time_partitions
WHERE parent_table = parent_table_name
AND to_value IS NOT NULL
AND to_value::timestamptz <= older_than
AND access_method <> new_access_method
ORDER BY to_value::timestamptz
LOOP
RAISE NOTICE 'converting % with start time % and end time %', r.partition, r.from_value, r.to_value;
PERFORM pg_catalog.alter_table_set_access_method(r.partition, new_access_method);
COMMIT;
END LOOP;
END;
$$;
COMMENT ON PROCEDURE pg_catalog.alter_old_partitions_set_access_method(
parent_table_name regclass,
older_than timestamptz,
new_access_method name)
IS 'convert old partitions of a time-partitioned table to a new access method';

View File

@ -176,6 +176,120 @@ SELECT * FROM partitioned_table_6_10 ORDER BY 1, 2;
7 | 2
(1 row)
-- try to compress partitions with an integer partition column
CALL alter_old_partitions_set_access_method('partitioned_table', '2021-01-01', 'columnar');
ERROR: partition column of partitioned_table cannot be cast to a timestamptz
CONTEXT: PL/pgSQL function alter_old_partitions_set_access_method(regclass,timestamp with time zone,name) line 13 at RAISE
CREATE TABLE time_partitioned (event_time timestamp, event int) partition by range (event_time);
SELECT create_distributed_table('time_partitioned', 'event_time');
create_distributed_table
---------------------------------------------------------------------
(1 row)
CREATE TABLE time_partitioned_d00 PARTITION OF time_partitioned FOR VALUES FROM ('2000-01-01') TO ('2009-12-31');
CREATE TABLE time_partitioned_d10 PARTITION OF time_partitioned FOR VALUES FROM ('2010-01-01') TO ('2019-12-31');
CREATE TABLE time_partitioned_d20 PARTITION OF time_partitioned FOR VALUES FROM ('2020-01-01') TO ('2029-12-31');
INSERT INTO time_partitioned VALUES ('2005-01-01', 1);
INSERT INTO time_partitioned VALUES ('2015-01-01', 2);
INSERT INTO time_partitioned VALUES ('2025-01-01', 3);
\set VERBOSITY terse
-- compress no partitions
CALL alter_old_partitions_set_access_method('time_partitioned', '1999-01-01', 'columnar');
SELECT partition, access_method FROM time_partitions WHERE parent_table = 'time_partitioned'::regclass ORDER BY partition::text;
partition | access_method
---------------------------------------------------------------------
time_partitioned_d00 | heap
time_partitioned_d10 | heap
time_partitioned_d20 | heap
(3 rows)
SELECT event FROM time_partitioned ORDER BY 1;
event
---------------------------------------------------------------------
1
2
3
(3 rows)
-- compress 2 old partitions
CALL alter_old_partitions_set_access_method('time_partitioned', '2021-01-01', 'columnar');
NOTICE: converting time_partitioned_d00 with start time Sat Jan 01 00:00:00 2000 and end time Thu Dec 31 00:00:00 2009
NOTICE: any index will be dropped, because columnar tables cannot have indexes
NOTICE: creating a new table for alter_table_set_access_method.time_partitioned_d00
NOTICE: Moving the data of alter_table_set_access_method.time_partitioned_d00
NOTICE: Dropping the old alter_table_set_access_method.time_partitioned_d00
NOTICE: Renaming the new table to alter_table_set_access_method.time_partitioned_d00
NOTICE: converting time_partitioned_d10 with start time Fri Jan 01 00:00:00 2010 and end time Tue Dec 31 00:00:00 2019
NOTICE: any index will be dropped, because columnar tables cannot have indexes
NOTICE: creating a new table for alter_table_set_access_method.time_partitioned_d10
NOTICE: Moving the data of alter_table_set_access_method.time_partitioned_d10
NOTICE: Dropping the old alter_table_set_access_method.time_partitioned_d10
NOTICE: Renaming the new table to alter_table_set_access_method.time_partitioned_d10
SELECT partition, access_method FROM time_partitions WHERE parent_table = 'time_partitioned'::regclass ORDER BY partition::text;
partition | access_method
---------------------------------------------------------------------
time_partitioned_d00 | columnar
time_partitioned_d10 | columnar
time_partitioned_d20 | heap
(3 rows)
SELECT event FROM time_partitioned ORDER BY 1;
event
---------------------------------------------------------------------
1
2
3
(3 rows)
-- will not be compressed again
CALL alter_old_partitions_set_access_method('time_partitioned', '2021-01-01', 'columnar');
SELECT partition, access_method FROM time_partitions WHERE parent_table = 'time_partitioned'::regclass ORDER BY partition::text;
partition | access_method
---------------------------------------------------------------------
time_partitioned_d00 | columnar
time_partitioned_d10 | columnar
time_partitioned_d20 | heap
(3 rows)
SELECT event FROM time_partitioned ORDER BY 1;
event
---------------------------------------------------------------------
1
2
3
(3 rows)
-- back to heap
CALL alter_old_partitions_set_access_method('time_partitioned', '2021-01-01', 'heap');
NOTICE: converting time_partitioned_d00 with start time Sat Jan 01 00:00:00 2000 and end time Thu Dec 31 00:00:00 2009
NOTICE: creating a new table for alter_table_set_access_method.time_partitioned_d00
NOTICE: Moving the data of alter_table_set_access_method.time_partitioned_d00
NOTICE: Dropping the old alter_table_set_access_method.time_partitioned_d00
NOTICE: Renaming the new table to alter_table_set_access_method.time_partitioned_d00
NOTICE: converting time_partitioned_d10 with start time Fri Jan 01 00:00:00 2010 and end time Tue Dec 31 00:00:00 2019
NOTICE: creating a new table for alter_table_set_access_method.time_partitioned_d10
NOTICE: Moving the data of alter_table_set_access_method.time_partitioned_d10
NOTICE: Dropping the old alter_table_set_access_method.time_partitioned_d10
NOTICE: Renaming the new table to alter_table_set_access_method.time_partitioned_d10
SELECT partition, access_method FROM time_partitions WHERE parent_table = 'time_partitioned'::regclass ORDER BY partition::text;
partition | access_method
---------------------------------------------------------------------
time_partitioned_d00 | heap
time_partitioned_d10 | heap
time_partitioned_d20 | heap
(3 rows)
SELECT event FROM time_partitioned ORDER BY 1;
event
---------------------------------------------------------------------
1
2
3
(3 rows)
\set VERBOSITY default
DROP TABLE time_partitioned;
-- test altering a table with index to columnar
-- the index will be dropped
CREATE TABLE index_table (a INT) ;

View File

@ -464,6 +464,7 @@ SELECT * FROM print_extension_changes();
| function alter_columnar_table_reset(regclass,boolean,boolean,boolean,boolean)
| function alter_columnar_table_set(regclass,integer,integer,name,integer)
| function alter_distributed_table(regclass,text,integer,text,boolean)
| function alter_old_partitions_set_access_method(regclass,timestamp with time zone,name)
| function alter_table_set_access_method(regclass,text)
| function citus_activate_node(text,integer)
| function citus_add_inactive_node(text,integer,integer,noderole,name)
@ -504,7 +505,7 @@ SELECT * FROM print_extension_changes();
| view citus_shards
| view citus_tables
| view time_partitions
(59 rows)
(60 rows)
DROP TABLE prev_objects, extension_diff;
-- show running version

View File

@ -461,6 +461,7 @@ SELECT * FROM print_extension_changes();
function undistribute_table(regclass) |
function upgrade_to_reference_table(regclass) |
| function alter_distributed_table(regclass,text,integer,text,boolean)
| function alter_old_partitions_set_access_method(regclass,timestamp with time zone,name)
| function alter_table_set_access_method(regclass,text)
| function citus_activate_node(text,integer)
| function citus_add_inactive_node(text,integer,integer,noderole,name)
@ -500,7 +501,7 @@ SELECT * FROM print_extension_changes();
| view citus_shards
| view citus_tables
| view time_partitions
(55 rows)
(56 rows)
DROP TABLE prev_objects, extension_diff;
-- show running version

View File

@ -21,6 +21,7 @@ ORDER BY 1;
function alter_columnar_table_reset(regclass,boolean,boolean,boolean,boolean)
function alter_columnar_table_set(regclass,integer,integer,name,integer)
function alter_distributed_table(regclass,text,integer,text,boolean)
function alter_old_partitions_set_access_method(regclass,timestamp with time zone,name)
function alter_role_if_exists(text,text)
function alter_table_set_access_method(regclass,text)
function any_value(anyelement)
@ -236,5 +237,5 @@ ORDER BY 1;
view citus_worker_stat_activity
view pg_dist_shard_placement
view time_partitions
(220 rows)
(221 rows)

View File

@ -18,6 +18,7 @@ ORDER BY 1;
---------------------------------------------------------------------
event trigger citus_cascade_to_partition
function alter_distributed_table(regclass,text,integer,text,boolean)
function alter_old_partitions_set_access_method(regclass,timestamp with time zone,name)
function alter_role_if_exists(text,text)
function alter_table_set_access_method(regclass,text)
function any_value(anyelement)
@ -232,5 +233,5 @@ ORDER BY 1;
view citus_worker_stat_activity
view pg_dist_shard_placement
view time_partitions
(216 rows)
(217 rows)

View File

@ -57,6 +57,43 @@ SELECT * FROM partitioned_table ORDER BY 1, 2;
SELECT * FROM partitioned_table_1_5 ORDER BY 1, 2;
SELECT * FROM partitioned_table_6_10 ORDER BY 1, 2;
-- try to compress partitions with an integer partition column
CALL alter_old_partitions_set_access_method('partitioned_table', '2021-01-01', 'columnar');
CREATE TABLE time_partitioned (event_time timestamp, event int) partition by range (event_time);
SELECT create_distributed_table('time_partitioned', 'event_time');
CREATE TABLE time_partitioned_d00 PARTITION OF time_partitioned FOR VALUES FROM ('2000-01-01') TO ('2009-12-31');
CREATE TABLE time_partitioned_d10 PARTITION OF time_partitioned FOR VALUES FROM ('2010-01-01') TO ('2019-12-31');
CREATE TABLE time_partitioned_d20 PARTITION OF time_partitioned FOR VALUES FROM ('2020-01-01') TO ('2029-12-31');
INSERT INTO time_partitioned VALUES ('2005-01-01', 1);
INSERT INTO time_partitioned VALUES ('2015-01-01', 2);
INSERT INTO time_partitioned VALUES ('2025-01-01', 3);
\set VERBOSITY terse
-- compress no partitions
CALL alter_old_partitions_set_access_method('time_partitioned', '1999-01-01', 'columnar');
SELECT partition, access_method FROM time_partitions WHERE parent_table = 'time_partitioned'::regclass ORDER BY partition::text;
SELECT event FROM time_partitioned ORDER BY 1;
-- compress 2 old partitions
CALL alter_old_partitions_set_access_method('time_partitioned', '2021-01-01', 'columnar');
SELECT partition, access_method FROM time_partitions WHERE parent_table = 'time_partitioned'::regclass ORDER BY partition::text;
SELECT event FROM time_partitioned ORDER BY 1;
-- will not be compressed again
CALL alter_old_partitions_set_access_method('time_partitioned', '2021-01-01', 'columnar');
SELECT partition, access_method FROM time_partitions WHERE parent_table = 'time_partitioned'::regclass ORDER BY partition::text;
SELECT event FROM time_partitioned ORDER BY 1;
-- back to heap
CALL alter_old_partitions_set_access_method('time_partitioned', '2021-01-01', 'heap');
SELECT partition, access_method FROM time_partitions WHERE parent_table = 'time_partitioned'::regclass ORDER BY partition::text;
SELECT event FROM time_partitioned ORDER BY 1;
\set VERBOSITY default
DROP TABLE time_partitioned;
-- test altering a table with index to columnar
-- the index will be dropped