From 868c522d1f45f27461df5fdebc57467c6969748a Mon Sep 17 00:00:00 2001 From: Burak Velioglu Date: Sat, 28 Aug 2021 22:12:20 +0300 Subject: [PATCH] Return partition name from range finder function (without fixing tests) --- .../udfs/create_missing_partitions/10.2-1.sql | 19 ++----- .../udfs/create_missing_partitions/latest.sql | 19 ++----- .../get_missing_partition_ranges/10.2-1.sql | 56 +++++++++++++++++-- .../get_missing_partition_ranges/latest.sql | 56 +++++++++++++++++-- 4 files changed, 110 insertions(+), 40 deletions(-) diff --git a/src/backend/timeseries/sql/udfs/create_missing_partitions/10.2-1.sql b/src/backend/timeseries/sql/udfs/create_missing_partitions/10.2-1.sql index ea19a18b9..86d9d0e9b 100644 --- a/src/backend/timeseries/sql/udfs/create_missing_partitions/10.2-1.sql +++ b/src/backend/timeseries/sql/udfs/create_missing_partitions/10.2-1.sql @@ -6,32 +6,23 @@ returns boolean LANGUAGE plpgsql AS $$ DECLARE - range_values_record record; - current_partition_name text; - current_partition_count int; + missing_partition_record record; BEGIN /* - * Get the partition ranges using the get_missing_partition_ranges and create - * partitions for those ranges. Since timeseries table related checks are + * Get missing partition range info using the get_missing_partition_ranges + * and create partitions using that info. Since timeseries table related checks are * handled by get_missing_partition_range we don't check them here again. * * TODO: Create that using attach partition, which can be implemented with another UDF to make sure that it gets right locks. * Consider different types of tables while implemented that (Task 1.3 on sheet) */ - SELECT count(*) - INTO current_partition_count - FROM pg_catalog.time_partitions - WHERE parent_table = table_name; - - FOR range_values_record IN + FOR missing_partition_record IN SELECT * FROM get_missing_partition_ranges(table_name, to_date, start_from) LOOP - current_partition_name := table_name::text || '_' || current_partition_count::text; - EXECUTE format('CREATE TABLE %I PARTITION OF %I FOR VALUES FROM (''%I'') TO (''%I'')', current_partition_name, table_name::text, range_values_record.range_from_value, range_values_record.range_to_value); - current_partition_count := current_partition_count + 1; + EXECUTE format('CREATE TABLE %I PARTITION OF %I FOR VALUES FROM (''%I'') TO (''%I'')', missing_partition_record.partition_name, table_name::text, missing_partition_record.range_from_value, missing_partition_record.range_to_value); END LOOP; RETURN true; diff --git a/src/backend/timeseries/sql/udfs/create_missing_partitions/latest.sql b/src/backend/timeseries/sql/udfs/create_missing_partitions/latest.sql index ea19a18b9..86d9d0e9b 100644 --- a/src/backend/timeseries/sql/udfs/create_missing_partitions/latest.sql +++ b/src/backend/timeseries/sql/udfs/create_missing_partitions/latest.sql @@ -6,32 +6,23 @@ returns boolean LANGUAGE plpgsql AS $$ DECLARE - range_values_record record; - current_partition_name text; - current_partition_count int; + missing_partition_record record; BEGIN /* - * Get the partition ranges using the get_missing_partition_ranges and create - * partitions for those ranges. Since timeseries table related checks are + * Get missing partition range info using the get_missing_partition_ranges + * and create partitions using that info. Since timeseries table related checks are * handled by get_missing_partition_range we don't check them here again. * * TODO: Create that using attach partition, which can be implemented with another UDF to make sure that it gets right locks. * Consider different types of tables while implemented that (Task 1.3 on sheet) */ - SELECT count(*) - INTO current_partition_count - FROM pg_catalog.time_partitions - WHERE parent_table = table_name; - - FOR range_values_record IN + FOR missing_partition_record IN SELECT * FROM get_missing_partition_ranges(table_name, to_date, start_from) LOOP - current_partition_name := table_name::text || '_' || current_partition_count::text; - EXECUTE format('CREATE TABLE %I PARTITION OF %I FOR VALUES FROM (''%I'') TO (''%I'')', current_partition_name, table_name::text, range_values_record.range_from_value, range_values_record.range_to_value); - current_partition_count := current_partition_count + 1; + EXECUTE format('CREATE TABLE %I PARTITION OF %I FOR VALUES FROM (''%I'') TO (''%I'')', missing_partition_record.partition_name, table_name::text, missing_partition_record.range_from_value, missing_partition_record.range_to_value); END LOOP; RETURN true; diff --git a/src/backend/timeseries/sql/udfs/get_missing_partition_ranges/10.2-1.sql b/src/backend/timeseries/sql/udfs/get_missing_partition_ranges/10.2-1.sql index b4505aff7..50c38ff61 100644 --- a/src/backend/timeseries/sql/udfs/get_missing_partition_ranges/10.2-1.sql +++ b/src/backend/timeseries/sql/udfs/get_missing_partition_ranges/10.2-1.sql @@ -3,6 +3,7 @@ CREATE OR REPLACE FUNCTION pg_catalog.get_missing_partition_ranges( to_date timestamptz, start_from timestamptz DEFAULT NULL) returns table( + partition_name text, range_from_value text, range_to_value text) LANGUAGE plpgsql @@ -13,6 +14,11 @@ DECLARE table_partition_column_type_name text; current_range_from_value timestamptz := NULL; current_range_to_value timestamptz := NULL; + current_range_from_value_text text; + current_range_to_value_text text; + current_range_from_value_text_in_table_name text; + current_range_to_value_text_in_table_name text; + max_table_name_length int; BEGIN /* * First check whether such timeseries table exists. If not, error out. @@ -50,6 +56,13 @@ BEGIN ORDER BY from_value::timestamptz ASC LIMIT 1; + /* + * start_from must be less than the existing initial value + */ + IF start_from >= current_range_from_value THEN + RAISE 'given start_from value must be before any of the existing partition ranges'; + END IF; + WHILE current_range_from_value > start_from LOOP current_range_from_value := current_range_from_value - table_partition_interval; END LOOP; @@ -106,6 +119,11 @@ BEGIN WHERE attrelid = table_name::oid AND attnum = (select partattrs[0] from pg_partitioned_table where partrelid = table_name::oid); + SELECT max_val + INTO max_table_name_length + FROM pg_settings + WHERE name = 'max_identifier_length'; + WHILE current_range_from_value < to_date LOOP /* * Check whether partition with given range has already been created @@ -113,7 +131,10 @@ BEGIN * that we are comparing same type of parameters */ PERFORM * FROM pg_catalog.time_partitions - WHERE from_value::timestamptz = current_range_from_value::timestamptz AND to_value::timestamptz = current_range_to_value::timestamptz; + WHERE + from_value::timestamptz = current_range_from_value::timestamptz AND + to_value::timestamptz = current_range_to_value::timestamptz AND + parent_table = table_name; IF found THEN current_range_from_value := current_range_to_value; current_range_to_value := current_range_to_value + table_partition_interval; @@ -125,22 +146,45 @@ BEGIN * That means some partitions have been created manually and we must error out. */ PERFORM * FROM pg_catalog.time_partitions - WHERE (current_range_from_value::timestamptz > from_value::timestamptz AND current_range_from_value < to_value::timestamptz) OR - (current_range_to_value::timestamptz > from_value::timestamptz AND current_range_to_value::timestamptz < to_value::timestamptz); + WHERE + ((current_range_from_value::timestamptz > from_value::timestamptz AND current_range_from_value < to_value::timestamptz) OR + (current_range_to_value::timestamptz > from_value::timestamptz AND current_range_to_value::timestamptz < to_value::timestamptz)) AND + parent_table = table_name; IF found THEN RAISE 'For the table % manual partition(s) has been created, Please remove them to continue using that table as timeseries table', table_name; END IF; IF table_partition_column_type_name = 'date' THEN - RETURN QUERY SELECT current_range_from_value::date::text, current_range_to_value::date::text; + SELECT current_range_from_value::date::text INTO current_range_from_value_text; + SELECT current_range_to_value::date::text INTO current_range_to_value_text; + SELECT to_char(current_range_from_value, 'YYYY_MM_DD') INTO current_range_from_value_text_in_table_name; + SELECT to_char(current_range_to_value, 'YYYY_MM_DD') INTO current_range_to_value_text_in_table_name; ELSIF table_partition_column_type_name = 'timestamp without time zone' THEN - RETURN QUERY SELECT current_range_from_value::timestamp::text, current_range_to_value::timestamp::text; + SELECT current_range_from_value::timestamp::text INTO current_range_from_value_text; + SELECT current_range_to_value::timestamp::text INTO current_range_to_value_text; + SELECT to_char(current_range_from_value, 'YYYY_MM_DD_HH24_MI_SS') INTO current_range_from_value_text_in_table_name; + SELECT to_char(current_range_to_value, 'YYYY_MM_DD_HH24_MI_SS') INTO current_range_to_value_text_in_table_name; ELSIF table_partition_column_type_name = 'timestamp with time zone' THEN - RETURN QUERY SELECT current_range_from_value::timestamptz::text, current_range_to_value::timestamptz::text; + SELECT current_range_from_value::timestamptz::text INTO current_range_from_value_text; + SELECT current_range_to_value::timestamptz::text INTO current_range_to_value_text; + SELECT translate(to_char(current_range_from_value, 'YYYY_MM_DD_HH24_MI_SS_TZ'), '+', '') INTO current_range_from_value_text_in_table_name; + SELECT translate(to_char(current_range_to_value, 'YYYY_MM_DD_HH24_MI_SS_TZ'), '+', '') INTO current_range_to_value_text_in_table_name; ELSE RAISE 'type of the partition column of the table % must be date, timestamp or timestamptz', table_name; END IF; + /* + * Use range values within the name of partition to have unique partition names. We need to + * convert values which are not proper for table to '_'. + */ + RETURN QUERY + SELECT + substring(table_name::text, 0, max_table_name_length - length(current_range_from_value_text_in_table_name) - length(current_range_to_value_text_in_table_name) - 1) || '_' || + current_range_from_value_text_in_table_name || '_' || + current_range_to_value_text_in_table_name, + current_range_from_value_text, + current_range_to_value_text; + current_range_from_value := current_range_to_value; current_range_to_value := current_range_to_value + table_partition_interval; END LOOP; diff --git a/src/backend/timeseries/sql/udfs/get_missing_partition_ranges/latest.sql b/src/backend/timeseries/sql/udfs/get_missing_partition_ranges/latest.sql index b4505aff7..50c38ff61 100644 --- a/src/backend/timeseries/sql/udfs/get_missing_partition_ranges/latest.sql +++ b/src/backend/timeseries/sql/udfs/get_missing_partition_ranges/latest.sql @@ -3,6 +3,7 @@ CREATE OR REPLACE FUNCTION pg_catalog.get_missing_partition_ranges( to_date timestamptz, start_from timestamptz DEFAULT NULL) returns table( + partition_name text, range_from_value text, range_to_value text) LANGUAGE plpgsql @@ -13,6 +14,11 @@ DECLARE table_partition_column_type_name text; current_range_from_value timestamptz := NULL; current_range_to_value timestamptz := NULL; + current_range_from_value_text text; + current_range_to_value_text text; + current_range_from_value_text_in_table_name text; + current_range_to_value_text_in_table_name text; + max_table_name_length int; BEGIN /* * First check whether such timeseries table exists. If not, error out. @@ -50,6 +56,13 @@ BEGIN ORDER BY from_value::timestamptz ASC LIMIT 1; + /* + * start_from must be less than the existing initial value + */ + IF start_from >= current_range_from_value THEN + RAISE 'given start_from value must be before any of the existing partition ranges'; + END IF; + WHILE current_range_from_value > start_from LOOP current_range_from_value := current_range_from_value - table_partition_interval; END LOOP; @@ -106,6 +119,11 @@ BEGIN WHERE attrelid = table_name::oid AND attnum = (select partattrs[0] from pg_partitioned_table where partrelid = table_name::oid); + SELECT max_val + INTO max_table_name_length + FROM pg_settings + WHERE name = 'max_identifier_length'; + WHILE current_range_from_value < to_date LOOP /* * Check whether partition with given range has already been created @@ -113,7 +131,10 @@ BEGIN * that we are comparing same type of parameters */ PERFORM * FROM pg_catalog.time_partitions - WHERE from_value::timestamptz = current_range_from_value::timestamptz AND to_value::timestamptz = current_range_to_value::timestamptz; + WHERE + from_value::timestamptz = current_range_from_value::timestamptz AND + to_value::timestamptz = current_range_to_value::timestamptz AND + parent_table = table_name; IF found THEN current_range_from_value := current_range_to_value; current_range_to_value := current_range_to_value + table_partition_interval; @@ -125,22 +146,45 @@ BEGIN * That means some partitions have been created manually and we must error out. */ PERFORM * FROM pg_catalog.time_partitions - WHERE (current_range_from_value::timestamptz > from_value::timestamptz AND current_range_from_value < to_value::timestamptz) OR - (current_range_to_value::timestamptz > from_value::timestamptz AND current_range_to_value::timestamptz < to_value::timestamptz); + WHERE + ((current_range_from_value::timestamptz > from_value::timestamptz AND current_range_from_value < to_value::timestamptz) OR + (current_range_to_value::timestamptz > from_value::timestamptz AND current_range_to_value::timestamptz < to_value::timestamptz)) AND + parent_table = table_name; IF found THEN RAISE 'For the table % manual partition(s) has been created, Please remove them to continue using that table as timeseries table', table_name; END IF; IF table_partition_column_type_name = 'date' THEN - RETURN QUERY SELECT current_range_from_value::date::text, current_range_to_value::date::text; + SELECT current_range_from_value::date::text INTO current_range_from_value_text; + SELECT current_range_to_value::date::text INTO current_range_to_value_text; + SELECT to_char(current_range_from_value, 'YYYY_MM_DD') INTO current_range_from_value_text_in_table_name; + SELECT to_char(current_range_to_value, 'YYYY_MM_DD') INTO current_range_to_value_text_in_table_name; ELSIF table_partition_column_type_name = 'timestamp without time zone' THEN - RETURN QUERY SELECT current_range_from_value::timestamp::text, current_range_to_value::timestamp::text; + SELECT current_range_from_value::timestamp::text INTO current_range_from_value_text; + SELECT current_range_to_value::timestamp::text INTO current_range_to_value_text; + SELECT to_char(current_range_from_value, 'YYYY_MM_DD_HH24_MI_SS') INTO current_range_from_value_text_in_table_name; + SELECT to_char(current_range_to_value, 'YYYY_MM_DD_HH24_MI_SS') INTO current_range_to_value_text_in_table_name; ELSIF table_partition_column_type_name = 'timestamp with time zone' THEN - RETURN QUERY SELECT current_range_from_value::timestamptz::text, current_range_to_value::timestamptz::text; + SELECT current_range_from_value::timestamptz::text INTO current_range_from_value_text; + SELECT current_range_to_value::timestamptz::text INTO current_range_to_value_text; + SELECT translate(to_char(current_range_from_value, 'YYYY_MM_DD_HH24_MI_SS_TZ'), '+', '') INTO current_range_from_value_text_in_table_name; + SELECT translate(to_char(current_range_to_value, 'YYYY_MM_DD_HH24_MI_SS_TZ'), '+', '') INTO current_range_to_value_text_in_table_name; ELSE RAISE 'type of the partition column of the table % must be date, timestamp or timestamptz', table_name; END IF; + /* + * Use range values within the name of partition to have unique partition names. We need to + * convert values which are not proper for table to '_'. + */ + RETURN QUERY + SELECT + substring(table_name::text, 0, max_table_name_length - length(current_range_from_value_text_in_table_name) - length(current_range_to_value_text_in_table_name) - 1) || '_' || + current_range_from_value_text_in_table_name || '_' || + current_range_to_value_text_in_table_name, + current_range_from_value_text, + current_range_to_value_text; + current_range_from_value := current_range_to_value; current_range_to_value := current_range_to_value + table_partition_interval; END LOOP;