From 47ec669a71d9aac868d3c92e73e42127f83dee3a Mon Sep 17 00:00:00 2001 From: Burak Velioglu Date: Mon, 30 Aug 2021 12:36:33 +0300 Subject: [PATCH] Update tests and comments --- .../get_missing_partition_ranges/10.2-1.sql | 58 +++---- .../get_missing_partition_ranges/latest.sql | 58 +++---- ...imeseries_create_drop_timeseries_table.sql | 2 +- .../timeseries_create_missing_partitions.sql | 6 +- ...imeseries_get_missing_partition_ranges.sql | 143 ++++++++++++++++-- 5 files changed, 192 insertions(+), 75 deletions(-) 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 50c38ff61..e700eb793 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 @@ -16,8 +16,8 @@ DECLARE 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; + current_range_from_value_text_in_partition_name text; + current_range_to_value_text_in_partition_name text; max_table_name_length int; BEGIN /* @@ -56,9 +56,6 @@ 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; @@ -119,6 +116,9 @@ BEGIN WHERE attrelid = table_name::oid AND attnum = (select partattrs[0] from pg_partitioned_table where partrelid = table_name::oid); + /* + * Get max_table_name_length to use it while finding partitions' name + */ SELECT max_val INTO max_table_name_length FROM pg_settings @@ -127,8 +127,8 @@ BEGIN WHILE current_range_from_value < to_date LOOP /* * Check whether partition with given range has already been created - * Since partition interval can be given as, we are converting all variables to timestamptz to make sure - * that we are comparing same type of parameters + * Since partition interval can be given with different types, we are converting + * all variables to timestamptz to make sure that we are comparing same type of parameters */ PERFORM * FROM pg_catalog.time_partitions WHERE @@ -154,34 +154,34 @@ BEGIN 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 - 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 - 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 - 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 '_'. */ + IF table_partition_column_type_name = 'date' THEN + 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_partition_name; + SELECT to_char(current_range_to_value, 'YYYY_MM_DD') INTO current_range_to_value_text_in_partition_name; + ELSIF table_partition_column_type_name = 'timestamp without time zone' THEN + 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_partition_name; + SELECT to_char(current_range_to_value, 'YYYY_MM_DD_HH24_MI_SS') INTO current_range_to_value_text_in_partition_name; + ELSIF table_partition_column_type_name = 'timestamp with time zone' THEN + 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_partition_name; + SELECT translate(to_char(current_range_to_value, 'YYYY_MM_DD_HH24_MI_SS_TZ'), '+', '') INTO current_range_to_value_text_in_partition_name; + ELSE + RAISE 'type of the partition column of the table % must be date, timestamp or timestamptz', table_name; + END IF; + 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, + substring(table_name::text, 0, max_table_name_length - length(current_range_from_value_text_in_partition_name) - length(current_range_to_value_text_in_partition_name) - 1) || '_' || + current_range_from_value_text_in_partition_name || '_' || + current_range_to_value_text_in_partition_name, current_range_from_value_text, current_range_to_value_text; 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 50c38ff61..e700eb793 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 @@ -16,8 +16,8 @@ DECLARE 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; + current_range_from_value_text_in_partition_name text; + current_range_to_value_text_in_partition_name text; max_table_name_length int; BEGIN /* @@ -56,9 +56,6 @@ 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; @@ -119,6 +116,9 @@ BEGIN WHERE attrelid = table_name::oid AND attnum = (select partattrs[0] from pg_partitioned_table where partrelid = table_name::oid); + /* + * Get max_table_name_length to use it while finding partitions' name + */ SELECT max_val INTO max_table_name_length FROM pg_settings @@ -127,8 +127,8 @@ BEGIN WHILE current_range_from_value < to_date LOOP /* * Check whether partition with given range has already been created - * Since partition interval can be given as, we are converting all variables to timestamptz to make sure - * that we are comparing same type of parameters + * Since partition interval can be given with different types, we are converting + * all variables to timestamptz to make sure that we are comparing same type of parameters */ PERFORM * FROM pg_catalog.time_partitions WHERE @@ -154,34 +154,34 @@ BEGIN 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 - 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 - 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 - 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 '_'. */ + IF table_partition_column_type_name = 'date' THEN + 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_partition_name; + SELECT to_char(current_range_to_value, 'YYYY_MM_DD') INTO current_range_to_value_text_in_partition_name; + ELSIF table_partition_column_type_name = 'timestamp without time zone' THEN + 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_partition_name; + SELECT to_char(current_range_to_value, 'YYYY_MM_DD_HH24_MI_SS') INTO current_range_to_value_text_in_partition_name; + ELSIF table_partition_column_type_name = 'timestamp with time zone' THEN + 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_partition_name; + SELECT translate(to_char(current_range_to_value, 'YYYY_MM_DD_HH24_MI_SS_TZ'), '+', '') INTO current_range_to_value_text_in_partition_name; + ELSE + RAISE 'type of the partition column of the table % must be date, timestamp or timestamptz', table_name; + END IF; + 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, + substring(table_name::text, 0, max_table_name_length - length(current_range_from_value_text_in_partition_name) - length(current_range_to_value_text_in_partition_name) - 1) || '_' || + current_range_from_value_text_in_partition_name || '_' || + current_range_to_value_text_in_partition_name, current_range_from_value_text, current_range_to_value_text; diff --git a/src/test/regress/sql/timeseries_create_drop_timeseries_table.sql b/src/test/regress/sql/timeseries_create_drop_timeseries_table.sql index 1f5667442..c3bd8cfa3 100644 --- a/src/test/regress/sql/timeseries_create_drop_timeseries_table.sql +++ b/src/test/regress/sql/timeseries_create_drop_timeseries_table.sql @@ -79,7 +79,7 @@ ROLLBACK; DROP TABLE date_partitioned_table; -- 2) retention threshold must be greater than compression threshold and --- compresstion threshold must be greater than partition interval +-- compression threshold must be greater than partition interval -- With date partitioned table CREATE TABLE ts_comp_date_partitioned_table( diff --git a/src/test/regress/sql/timeseries_create_missing_partitions.sql b/src/test/regress/sql/timeseries_create_missing_partitions.sql index dc04a3542..ca3896e6b 100644 --- a/src/test/regress/sql/timeseries_create_missing_partitions.sql +++ b/src/test/regress/sql/timeseries_create_missing_partitions.sql @@ -42,10 +42,10 @@ ROLLBACK; BEGIN; SELECT create_timeseries_table('date_partitioned_table', INTERVAL '1 week'); - SELECT create_missing_partitions('date_partitioned_table', now() + INTERVAL '65 days', now() + INTERVAL '65 days'); + SELECT create_missing_partitions('date_partitioned_table', now() + INTERVAL '85 days', now() + INTERVAL '85 days'); SELECT - date_trunc('day', now()) - from_value::date as from_diff, - date_trunc('day', now()) - to_value::date as to_diff + date_trunc('week', now()) - from_value::date as from_diff, + date_trunc('week', now()) - to_value::date as to_diff FROM pg_catalog.time_partitions WHERE parent_table = 'date_partitioned_table'::regclass ORDER BY 1,2; diff --git a/src/test/regress/sql/timeseries_get_missing_partition_ranges.sql b/src/test/regress/sql/timeseries_get_missing_partition_ranges.sql index e339f2441..86c14f18c 100644 --- a/src/test/regress/sql/timeseries_get_missing_partition_ranges.sql +++ b/src/test/regress/sql/timeseries_get_missing_partition_ranges.sql @@ -1,4 +1,4 @@ --- Show get_missing_partition_ranges function can be only callede for timeseries tables +-- Show get_missing_partition_ranges function can be only called for timeseries tables CREATE TABLE date_partitioned_table( measureid integer, eventdate date, @@ -34,15 +34,7 @@ BEGIN; ORDER BY 1,2; ROLLBACK; -BEGIN; - SELECT create_timeseries_table('date_partitioned_table', INTERVAL '1 week'); - SELECT - date_trunc('week', now()) - range_from_value::date as from_diff, - date_trunc('week', now()) - range_to_value::date as to_diff - FROM get_missing_partition_ranges('date_partitioned_table', now() + INTERVAL '65 days', now() - INTERVAL '65 days') - ORDER BY 1,2; -ROLLBACK; - +-- Show start from date must be before any of existing partition ranges BEGIN; SELECT create_timeseries_table('date_partitioned_table', INTERVAL '1 day'); SELECT @@ -52,6 +44,17 @@ BEGIN; ORDER BY 1,2; ROLLBACK; +-- Show that table must not have manual partitions +BEGIN; + SELECT create_timeseries_table('date_partitioned_table', INTERVAL '1 day'); + CREATE TABLE date_partitioned_table_manual_partition PARTITION OF date_partitioned_table FOR VALUES FROM (now() + INTERVAL '15 days') TO (now() + INTERVAL '30 days'); + SELECT + date_trunc('day', now()) - range_from_value::date as from_diff, + date_trunc('day', now()) - range_to_value::date as to_diff + FROM get_missing_partition_ranges('date_partitioned_table', now() + INTERVAL '20 days', now() - INTERVAL '20 days') + ORDER BY 1,2; +ROLLBACK; + DROP TABLE date_partitioned_table; -- Show range values for timestamptz partitioned table @@ -80,6 +83,48 @@ ROLLBACK; BEGIN; SELECT create_timeseries_table('tstz_partitioned_table', INTERVAL '6 hours'); + SELECT + date_trunc('hour', now()) - range_from_value::timestamp with time zone as from_diff, + date_trunc('hour', now()) - range_to_value::timestamp with time zone as to_diff + FROM get_missing_partition_ranges('tstz_partitioned_table', now() + INTERVAL '5 days', now() - INTERVAL '5 days') + ORDER BY 1,2; +ROLLBACK; + +BEGIN; + SELECT create_timeseries_table('tstz_partitioned_table', INTERVAL '1 day'); + SELECT + date_trunc('day', now()) - range_from_value::timestamp with time zone as from_diff, + date_trunc('day', now()) - range_to_value::timestamp with time zone as to_diff + FROM get_missing_partition_ranges('tstz_partitioned_table', now() + INTERVAL '10 days', now() - INTERVAL '10 days') + ORDER BY 1,2; +ROLLBACK; + +-- Show start from date must be before any of existing partition ranges +BEGIN; + SELECT create_timeseries_table('tstz_partitioned_table', INTERVAL '1 day'); + SELECT + date_trunc('day', now()) - range_from_value::timestamp with time zone as from_diff, + date_trunc('day', now()) - range_to_value::timestamp with time zone as to_diff + FROM get_missing_partition_ranges('tstz_partitioned_table', now() + INTERVAL '10 days', now() - INTERVAL '5 days') + ORDER BY 1,2; +ROLLBACK; + +-- Show that table must not have manual partitions +BEGIN; + SELECT create_timeseries_table('tstz_partitioned_table', INTERVAL '1 day'); + CREATE TABLE tstz_partitioned_table_manual_partition PARTITION OF tstz_partitioned_table FOR VALUES FROM (now() + INTERVAL '15 days') TO (now() + INTERVAL '30 days'); + SELECT + date_trunc('day', now()) - range_from_value::timestamp with time zone as from_diff, + date_trunc('day', now()) - range_to_value::timestamp with time zone as to_diff + FROM get_missing_partition_ranges('tstz_partitioned_table', now() + INTERVAL '20 days', now() - INTERVAL '20 days') + ORDER BY 1,2; +ROLLBACK; + +-- Test with different time zones +SET timezone TO 'UTC'; + +BEGIN; + SELECT create_timeseries_table('tstz_partitioned_table', INTERVAL '1 hour'); SELECT date_trunc('hour', now()) - range_from_value::timestamp with time zone as from_diff, date_trunc('hour', now()) - range_to_value::timestamp with time zone as to_diff @@ -92,12 +137,74 @@ BEGIN; SELECT date_trunc('day', now()) - range_from_value::timestamp with time zone as from_diff, date_trunc('day', now()) - range_to_value::timestamp with time zone as to_diff - FROM get_missing_partition_ranges('tstz_partitioned_table', now() + INTERVAL '5 days', now() - INTERVAL '5 days') + FROM get_missing_partition_ranges('tstz_partitioned_table', now() + INTERVAL '10 days', now() - INTERVAL '10 days') + ORDER BY 1,2; +ROLLBACK; + +SET timezone TO 'WET'; + +BEGIN; + SELECT create_timeseries_table('tstz_partitioned_table', INTERVAL '1 hour'); + SELECT + date_trunc('hour', now()) - range_from_value::timestamp with time zone as from_diff, + date_trunc('hour', now()) - range_to_value::timestamp with time zone as to_diff + FROM get_missing_partition_ranges('tstz_partitioned_table', now() + INTERVAL '1 day', now() - INTERVAL '1 day') + ORDER BY 1,2; +ROLLBACK; + +BEGIN; + SELECT create_timeseries_table('tstz_partitioned_table', INTERVAL '1 day'); + SELECT + date_trunc('day', now()) - range_from_value::timestamp with time zone as from_diff, + date_trunc('day', now()) - range_to_value::timestamp with time zone as to_diff + FROM get_missing_partition_ranges('tstz_partitioned_table', now() + INTERVAL '10 days', now() - INTERVAL '10 days') + ORDER BY 1,2; +ROLLBACK; + +SET timezone TO 'IOT'; + +BEGIN; + SELECT create_timeseries_table('tstz_partitioned_table', INTERVAL '1 hour'); + SELECT + date_trunc('hour', now()) - range_from_value::timestamp with time zone as from_diff, + date_trunc('hour', now()) - range_to_value::timestamp with time zone as to_diff + FROM get_missing_partition_ranges('tstz_partitioned_table', now() + INTERVAL '1 day', now() - INTERVAL '1 day') + ORDER BY 1,2; +ROLLBACK; + +BEGIN; + SELECT create_timeseries_table('tstz_partitioned_table', INTERVAL '1 day'); + SELECT + date_trunc('day', now()) - range_from_value::timestamp with time zone as from_diff, + date_trunc('day', now()) - range_to_value::timestamp with time zone as to_diff + FROM get_missing_partition_ranges('tstz_partitioned_table', now() + INTERVAL '10 days', now() - INTERVAL '10 days') + ORDER BY 1,2; +ROLLBACK; + +SET timezone TO 'EST'; + +BEGIN; + SELECT create_timeseries_table('tstz_partitioned_table', INTERVAL '1 hour'); + SELECT + date_trunc('hour', now()) - range_from_value::timestamp with time zone as from_diff, + date_trunc('hour', now()) - range_to_value::timestamp with time zone as to_diff + FROM get_missing_partition_ranges('tstz_partitioned_table', now() + INTERVAL '1 day', now() - INTERVAL '1 day') + ORDER BY 1,2; +ROLLBACK; + +BEGIN; + SELECT create_timeseries_table('tstz_partitioned_table', INTERVAL '1 day'); + SELECT + date_trunc('day', now()) - range_from_value::timestamp with time zone as from_diff, + date_trunc('day', now()) - range_to_value::timestamp with time zone as to_diff + FROM get_missing_partition_ranges('tstz_partitioned_table', now() + INTERVAL '10 days', now() - INTERVAL '10 days') ORDER BY 1,2; ROLLBACK; DROP TABLE tstz_partitioned_table; +SET timezone to DEFAULT; + -- Show range values for timestamp without time zone partitioned table CREATE TABLE tswtz_partitioned_table( measureid integer, @@ -127,7 +234,7 @@ BEGIN; SELECT date_trunc('hour', now()) - range_from_value::timestamp without time zone as from_diff, date_trunc('hour', now()) - range_to_value::timestamp without time zone as to_diff - FROM get_missing_partition_ranges('tswtz_partitioned_table', now() + INTERVAL '1 day', now() - INTERVAL '1 day') + FROM get_missing_partition_ranges('tswtz_partitioned_table', now() + INTERVAL '5 days', now() - INTERVAL '5 days') ORDER BY 1,2; ROLLBACK; @@ -136,7 +243,17 @@ BEGIN; SELECT date_trunc('day', now()) - range_from_value::timestamp without time zone as from_diff, date_trunc('day', now()) - range_to_value::timestamp without time zone as to_diff - FROM get_missing_partition_ranges('tswtz_partitioned_table', now() + INTERVAL '5 days', now() - INTERVAL '5 days') + FROM get_missing_partition_ranges('tswtz_partitioned_table', now() + INTERVAL '10 days', now() - INTERVAL '10 days') + ORDER BY 1,2; +ROLLBACK; + +-- Show start from date must be before any of existing partition ranges +BEGIN; + SELECT create_timeseries_table('tswtz_partitioned_table', INTERVAL '1 day'); + SELECT + date_trunc('day', now()) - range_from_value::timestamp without time zone as from_diff, + date_trunc('day', now()) - range_to_value::timestamp without time zone as to_diff + FROM get_missing_partition_ranges('tswtz_partitioned_table', now() + INTERVAL '10 days', now() - INTERVAL '5 days') ORDER BY 1,2; ROLLBACK;