mirror of https://github.com/citusdata/citus.git
Merge pull request #5236 from citusdata/velioglu/partition_helper_udfs
Add helper UDFs for easy time partition managementpull/5243/head
commit
eada7f0bbc
|
@ -16,6 +16,9 @@ ALTER TABLE pg_catalog.pg_dist_placement ADD CONSTRAINT placement_shardid_groupi
|
|||
#include "udfs/citus_internal_update_placement_metadata/10.2-1.sql";
|
||||
#include "udfs/citus_internal_delete_shard_metadata/10.2-1.sql";
|
||||
#include "udfs/citus_internal_update_relation_colocation/10.2-1.sql";
|
||||
#include "udfs/create_time_partitions/10.2-1.sql"
|
||||
#include "udfs/drop_old_time_partitions/10.2-1.sql"
|
||||
#include "udfs/get_missing_time_partition_ranges/10.2-1.sql"
|
||||
|
||||
DROP FUNCTION pg_catalog.citus_drop_all_shards(regclass, text, text);
|
||||
CREATE FUNCTION pg_catalog.citus_drop_all_shards(logicalrelid regclass,
|
||||
|
|
|
@ -17,6 +17,10 @@ DROP FUNCTION pg_catalog.citus_internal_add_placement_metadata(bigint, integer,
|
|||
DROP FUNCTION pg_catalog.citus_internal_update_placement_metadata(bigint, integer, integer);
|
||||
DROP FUNCTION pg_catalog.citus_internal_delete_shard_metadata(bigint);
|
||||
DROP FUNCTION pg_catalog.citus_internal_update_relation_colocation(oid, integer);
|
||||
DROP FUNCTION pg_catalog.create_time_partitions(regclass, interval, timestamp with time zone, timestamp with time zone);
|
||||
DROP FUNCTION pg_catalog.get_missing_time_partition_ranges(regclass, interval, timestamp with time zone, timestamp with time zone);
|
||||
|
||||
DROP PROCEDURE pg_catalog.drop_old_time_partitions(regclass, timestamptz);
|
||||
|
||||
REVOKE ALL ON FUNCTION pg_catalog.worker_record_sequence_dependency(regclass,regclass,name) FROM PUBLIC;
|
||||
ALTER TABLE pg_catalog.pg_dist_placement DROP CONSTRAINT placement_shardid_groupid_unique_index;
|
||||
|
|
|
@ -0,0 +1,54 @@
|
|||
CREATE OR REPLACE FUNCTION pg_catalog.create_time_partitions(
|
||||
table_name regclass,
|
||||
partition_interval INTERVAL,
|
||||
end_at timestamptz,
|
||||
start_from timestamptz DEFAULT now())
|
||||
returns boolean
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
DECLARE
|
||||
-- partitioned table name
|
||||
schema_name_text name;
|
||||
table_name_text name;
|
||||
|
||||
-- record for to-be-created parttion
|
||||
missing_partition_record record;
|
||||
|
||||
-- result indiciates whether any partitions were created
|
||||
partition_created bool := false;
|
||||
BEGIN
|
||||
IF start_from >= end_at THEN
|
||||
RAISE 'start_from (%) must be older than end_at (%)', start_from, end_at;
|
||||
END IF;
|
||||
|
||||
SELECT nspname, relname
|
||||
INTO schema_name_text, table_name_text
|
||||
FROM pg_class JOIN pg_namespace ON pg_class.relnamespace = pg_namespace.oid
|
||||
WHERE pg_class.oid = table_name::oid;
|
||||
|
||||
-- Get missing partition range info using the get_missing_partition_ranges
|
||||
-- and create partitions using that info.
|
||||
FOR missing_partition_record IN
|
||||
SELECT *
|
||||
FROM get_missing_time_partition_ranges(table_name, partition_interval, end_at, start_from)
|
||||
LOOP
|
||||
EXECUTE format('CREATE TABLE %I.%I PARTITION OF %I.%I FOR VALUES FROM (%L) TO (%L)',
|
||||
schema_name_text,
|
||||
missing_partition_record.partition_name,
|
||||
schema_name_text,
|
||||
table_name_text,
|
||||
missing_partition_record.range_from_value,
|
||||
missing_partition_record.range_to_value);
|
||||
|
||||
partition_created := true;
|
||||
END LOOP;
|
||||
|
||||
RETURN partition_created;
|
||||
END;
|
||||
$$;
|
||||
COMMENT ON FUNCTION pg_catalog.create_time_partitions(
|
||||
table_name regclass,
|
||||
partition_interval INTERVAL,
|
||||
end_at timestamptz,
|
||||
start_from timestamptz)
|
||||
IS 'create time partitions for the given range';
|
|
@ -0,0 +1,54 @@
|
|||
CREATE OR REPLACE FUNCTION pg_catalog.create_time_partitions(
|
||||
table_name regclass,
|
||||
partition_interval INTERVAL,
|
||||
end_at timestamptz,
|
||||
start_from timestamptz DEFAULT now())
|
||||
returns boolean
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
DECLARE
|
||||
-- partitioned table name
|
||||
schema_name_text name;
|
||||
table_name_text name;
|
||||
|
||||
-- record for to-be-created parttion
|
||||
missing_partition_record record;
|
||||
|
||||
-- result indiciates whether any partitions were created
|
||||
partition_created bool := false;
|
||||
BEGIN
|
||||
IF start_from >= end_at THEN
|
||||
RAISE 'start_from (%) must be older than end_at (%)', start_from, end_at;
|
||||
END IF;
|
||||
|
||||
SELECT nspname, relname
|
||||
INTO schema_name_text, table_name_text
|
||||
FROM pg_class JOIN pg_namespace ON pg_class.relnamespace = pg_namespace.oid
|
||||
WHERE pg_class.oid = table_name::oid;
|
||||
|
||||
-- Get missing partition range info using the get_missing_partition_ranges
|
||||
-- and create partitions using that info.
|
||||
FOR missing_partition_record IN
|
||||
SELECT *
|
||||
FROM get_missing_time_partition_ranges(table_name, partition_interval, end_at, start_from)
|
||||
LOOP
|
||||
EXECUTE format('CREATE TABLE %I.%I PARTITION OF %I.%I FOR VALUES FROM (%L) TO (%L)',
|
||||
schema_name_text,
|
||||
missing_partition_record.partition_name,
|
||||
schema_name_text,
|
||||
table_name_text,
|
||||
missing_partition_record.range_from_value,
|
||||
missing_partition_record.range_to_value);
|
||||
|
||||
partition_created := true;
|
||||
END LOOP;
|
||||
|
||||
RETURN partition_created;
|
||||
END;
|
||||
$$;
|
||||
COMMENT ON FUNCTION pg_catalog.create_time_partitions(
|
||||
table_name regclass,
|
||||
partition_interval INTERVAL,
|
||||
end_at timestamptz,
|
||||
start_from timestamptz)
|
||||
IS 'create time partitions for the given range';
|
|
@ -0,0 +1,56 @@
|
|||
CREATE OR REPLACE PROCEDURE pg_catalog.drop_old_time_partitions(
|
||||
table_name regclass,
|
||||
older_than timestamptz)
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
DECLARE
|
||||
-- properties of the partitioned table
|
||||
number_of_partition_columns int;
|
||||
partition_column_index int;
|
||||
partition_column_type regtype;
|
||||
|
||||
r record;
|
||||
BEGIN
|
||||
-- check whether the table is time partitioned table, if not error out
|
||||
SELECT partnatts, partattrs[0]
|
||||
INTO number_of_partition_columns, partition_column_index
|
||||
FROM pg_catalog.pg_partitioned_table
|
||||
WHERE partrelid = table_name;
|
||||
|
||||
IF NOT FOUND THEN
|
||||
RAISE '% is not partitioned', table_name::text;
|
||||
ELSIF number_of_partition_columns <> 1 THEN
|
||||
RAISE 'partitioned tables with multiple partition columns are not supported';
|
||||
END IF;
|
||||
|
||||
-- get datatype here to check interval-table type
|
||||
SELECT atttypid
|
||||
INTO partition_column_type
|
||||
FROM pg_attribute
|
||||
WHERE attrelid = table_name::oid
|
||||
AND attnum = partition_column_index;
|
||||
|
||||
-- we currently only support partitioning by date, timestamp, and timestamptz
|
||||
IF partition_column_type <> 'date'::regtype
|
||||
AND partition_column_type <> 'timestamp'::regtype
|
||||
AND partition_column_type <> 'timestamptz'::regtype THEN
|
||||
RAISE 'type of the partition column of the table % must be date, timestamp or timestamptz', table_name;
|
||||
END IF;
|
||||
|
||||
FOR r IN
|
||||
SELECT partition, nspname AS schema_name, relname AS table_name, from_value, to_value
|
||||
FROM pg_catalog.time_partitions, pg_catalog.pg_class c, pg_catalog.pg_namespace n
|
||||
WHERE parent_table = table_name AND partition = c.oid AND c.relnamespace = n.oid
|
||||
AND to_value IS NOT NULL
|
||||
AND to_value::timestamptz <= older_than
|
||||
ORDER BY to_value::timestamptz
|
||||
LOOP
|
||||
RAISE NOTICE 'dropping % with start time % and end time %', r.partition, r.from_value, r.to_value;
|
||||
EXECUTE format('DROP TABLE %I.%I', r.schema_name, r.table_name);
|
||||
END LOOP;
|
||||
END;
|
||||
$$;
|
||||
COMMENT ON PROCEDURE pg_catalog.drop_old_time_partitions(
|
||||
table_name regclass,
|
||||
older_than timestamptz)
|
||||
IS 'drop old partitions of a time-partitioned table';
|
|
@ -0,0 +1,56 @@
|
|||
CREATE OR REPLACE PROCEDURE pg_catalog.drop_old_time_partitions(
|
||||
table_name regclass,
|
||||
older_than timestamptz)
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
DECLARE
|
||||
-- properties of the partitioned table
|
||||
number_of_partition_columns int;
|
||||
partition_column_index int;
|
||||
partition_column_type regtype;
|
||||
|
||||
r record;
|
||||
BEGIN
|
||||
-- check whether the table is time partitioned table, if not error out
|
||||
SELECT partnatts, partattrs[0]
|
||||
INTO number_of_partition_columns, partition_column_index
|
||||
FROM pg_catalog.pg_partitioned_table
|
||||
WHERE partrelid = table_name;
|
||||
|
||||
IF NOT FOUND THEN
|
||||
RAISE '% is not partitioned', table_name::text;
|
||||
ELSIF number_of_partition_columns <> 1 THEN
|
||||
RAISE 'partitioned tables with multiple partition columns are not supported';
|
||||
END IF;
|
||||
|
||||
-- get datatype here to check interval-table type
|
||||
SELECT atttypid
|
||||
INTO partition_column_type
|
||||
FROM pg_attribute
|
||||
WHERE attrelid = table_name::oid
|
||||
AND attnum = partition_column_index;
|
||||
|
||||
-- we currently only support partitioning by date, timestamp, and timestamptz
|
||||
IF partition_column_type <> 'date'::regtype
|
||||
AND partition_column_type <> 'timestamp'::regtype
|
||||
AND partition_column_type <> 'timestamptz'::regtype THEN
|
||||
RAISE 'type of the partition column of the table % must be date, timestamp or timestamptz', table_name;
|
||||
END IF;
|
||||
|
||||
FOR r IN
|
||||
SELECT partition, nspname AS schema_name, relname AS table_name, from_value, to_value
|
||||
FROM pg_catalog.time_partitions, pg_catalog.pg_class c, pg_catalog.pg_namespace n
|
||||
WHERE parent_table = table_name AND partition = c.oid AND c.relnamespace = n.oid
|
||||
AND to_value IS NOT NULL
|
||||
AND to_value::timestamptz <= older_than
|
||||
ORDER BY to_value::timestamptz
|
||||
LOOP
|
||||
RAISE NOTICE 'dropping % with start time % and end time %', r.partition, r.from_value, r.to_value;
|
||||
EXECUTE format('DROP TABLE %I.%I', r.schema_name, r.table_name);
|
||||
END LOOP;
|
||||
END;
|
||||
$$;
|
||||
COMMENT ON PROCEDURE pg_catalog.drop_old_time_partitions(
|
||||
table_name regclass,
|
||||
older_than timestamptz)
|
||||
IS 'drop old partitions of a time-partitioned table';
|
219
src/backend/distributed/sql/udfs/get_missing_time_partition_ranges/10.2-1.sql
generated
Normal file
219
src/backend/distributed/sql/udfs/get_missing_time_partition_ranges/10.2-1.sql
generated
Normal file
|
@ -0,0 +1,219 @@
|
|||
CREATE OR REPLACE FUNCTION pg_catalog.get_missing_time_partition_ranges(
|
||||
table_name regclass,
|
||||
partition_interval INTERVAL,
|
||||
to_value timestamptz,
|
||||
from_value timestamptz DEFAULT now())
|
||||
returns table(
|
||||
partition_name text,
|
||||
range_from_value text,
|
||||
range_to_value text)
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
DECLARE
|
||||
-- properties of the partitioned table
|
||||
table_name_text text;
|
||||
table_schema_text text;
|
||||
number_of_partition_columns int;
|
||||
partition_column_index int;
|
||||
partition_column_type regtype;
|
||||
|
||||
-- used for generating time ranges
|
||||
current_range_from_value timestamptz := NULL;
|
||||
current_range_to_value timestamptz := NULL;
|
||||
current_range_from_value_text text;
|
||||
current_range_to_value_text text;
|
||||
|
||||
-- used to check whether there are misaligned (manually created) partitions
|
||||
manual_partition regclass;
|
||||
manual_partition_from_value_text text;
|
||||
manual_partition_to_value_text text;
|
||||
|
||||
-- used for partition naming
|
||||
partition_name_format text;
|
||||
max_table_name_length int := current_setting('max_identifier_length');
|
||||
|
||||
-- used to determine whether the partition_interval is a day multiple
|
||||
is_day_multiple boolean;
|
||||
BEGIN
|
||||
-- check whether the table is time partitioned table, if not error out
|
||||
SELECT relname, nspname, partnatts, partattrs[0]
|
||||
INTO table_name_text, table_schema_text, number_of_partition_columns, partition_column_index
|
||||
FROM pg_catalog.pg_partitioned_table, pg_catalog.pg_class c, pg_catalog.pg_namespace n
|
||||
WHERE partrelid = c.oid AND c.oid = table_name
|
||||
AND c.relnamespace = n.oid;
|
||||
IF NOT FOUND THEN
|
||||
RAISE '% is not partitioned', table_name;
|
||||
ELSIF number_of_partition_columns <> 1 THEN
|
||||
RAISE 'partitioned tables with multiple partition columns are not supported';
|
||||
END IF;
|
||||
|
||||
-- to not to have partitions to be created in parallel
|
||||
EXECUTE format('LOCK TABLE %I.%I IN SHARE UPDATE EXCLUSIVE MODE', table_schema_text, table_name_text);
|
||||
|
||||
-- get datatype here to check interval-table type alignment and generate range values in the right data format
|
||||
SELECT atttypid
|
||||
INTO partition_column_type
|
||||
FROM pg_attribute
|
||||
WHERE attrelid = table_name::oid
|
||||
AND attnum = partition_column_index;
|
||||
|
||||
-- we currently only support partitioning by date, timestamp, and timestamptz
|
||||
IF partition_column_type <> 'date'::regtype
|
||||
AND partition_column_type <> 'timestamp'::regtype
|
||||
AND partition_column_type <> 'timestamptz'::regtype THEN
|
||||
RAISE 'type of the partition column of the table % must be date, timestamp or timestamptz', table_name;
|
||||
END IF;
|
||||
|
||||
IF partition_column_type = 'date'::regtype AND partition_interval IS NOT NULL THEN
|
||||
SELECT date_trunc('day', partition_interval) = partition_interval
|
||||
INTO is_day_multiple;
|
||||
|
||||
IF NOT is_day_multiple THEN
|
||||
RAISE 'partition interval of date partitioned table must be day or multiple days';
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
-- If no partition exists, truncate from_value to find intuitive initial value.
|
||||
-- If any partition exist, use the initial partition as the pivot partition.
|
||||
-- tp.to_value and tp.from_value are equal to '', if default partition exists.
|
||||
SELECT tp.from_value::timestamptz, tp.to_value::timestamptz
|
||||
INTO current_range_from_value, current_range_to_value
|
||||
FROM pg_catalog.time_partitions tp
|
||||
WHERE parent_table = table_name AND tp.to_value <> '' AND tp.from_value <> ''
|
||||
ORDER BY tp.from_value::timestamptz ASC
|
||||
LIMIT 1;
|
||||
|
||||
IF NOT FOUND THEN
|
||||
-- Decide on the current_range_from_value of the initial partition according to interval of the table.
|
||||
-- Since we will create all other partitions by adding intervals, truncating given start time will provide
|
||||
-- more intuitive interval ranges, instead of starting from from_value directly.
|
||||
IF partition_interval < INTERVAL '1 hour' THEN
|
||||
current_range_from_value = date_trunc('minute', from_value);
|
||||
ELSIF partition_interval < INTERVAL '1 day' THEN
|
||||
current_range_from_value = date_trunc('hour', from_value);
|
||||
ELSIF partition_interval < INTERVAL '1 week' THEN
|
||||
current_range_from_value = date_trunc('day', from_value);
|
||||
ELSIF partition_interval < INTERVAL '1 month' THEN
|
||||
current_range_from_value = date_trunc('week', from_value);
|
||||
ELSIF partition_interval = INTERVAL '3 months' THEN
|
||||
current_range_from_value = date_trunc('quarter', from_value);
|
||||
ELSIF partition_interval < INTERVAL '1 year' THEN
|
||||
current_range_from_value = date_trunc('month', from_value);
|
||||
ELSE
|
||||
current_range_from_value = date_trunc('year', from_value);
|
||||
END IF;
|
||||
|
||||
current_range_to_value := current_range_from_value + partition_interval;
|
||||
ELSE
|
||||
-- if from_value is newer than pivot's from value, go forward, else go backward
|
||||
IF from_value >= current_range_from_value THEN
|
||||
WHILE current_range_from_value < from_value LOOP
|
||||
current_range_from_value := current_range_from_value + partition_interval;
|
||||
END LOOP;
|
||||
ELSE
|
||||
WHILE current_range_from_value > from_value LOOP
|
||||
current_range_from_value := current_range_from_value - partition_interval;
|
||||
END LOOP;
|
||||
END IF;
|
||||
current_range_to_value := current_range_from_value + partition_interval;
|
||||
END IF;
|
||||
|
||||
-- reuse pg_partman naming scheme for back-and-forth migration
|
||||
IF partition_interval = INTERVAL '3 months' THEN
|
||||
-- include quarter in partition name
|
||||
partition_name_format = 'YYYY"q"Q';
|
||||
ELSIF partition_interval = INTERVAL '1 week' THEN
|
||||
-- include week number in partition name
|
||||
partition_name_format := 'IYYY"w"IW';
|
||||
ELSE
|
||||
-- always start with the year
|
||||
partition_name_format := 'YYYY';
|
||||
|
||||
IF partition_interval < INTERVAL '1 year' THEN
|
||||
-- include month in partition name
|
||||
partition_name_format := partition_name_format || '_MM';
|
||||
END IF;
|
||||
|
||||
IF partition_interval < INTERVAL '1 month' THEN
|
||||
-- include day of month in partition name
|
||||
partition_name_format := partition_name_format || '_DD';
|
||||
END IF;
|
||||
|
||||
IF partition_interval < INTERVAL '1 day' THEN
|
||||
-- include time of day in partition name
|
||||
partition_name_format := partition_name_format || '_HH24MI';
|
||||
END IF;
|
||||
|
||||
IF partition_interval < INTERVAL '1 minute' THEN
|
||||
-- include seconds in time of day in partition name
|
||||
partition_name_format := partition_name_format || 'SS';
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
WHILE current_range_from_value < to_value LOOP
|
||||
-- Check whether partition with given range has already been created
|
||||
-- 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 tp
|
||||
WHERE
|
||||
tp.from_value::timestamptz = current_range_from_value::timestamptz AND
|
||||
tp.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 + partition_interval;
|
||||
CONTINUE;
|
||||
END IF;
|
||||
|
||||
-- Check whether any other partition covers from_value or to_value
|
||||
-- That means some partitions doesn't align with the initial partition.
|
||||
-- In other words, gap(s) exist between partitions which is not multiple of intervals.
|
||||
SELECT partition, tp.from_value::text, tp.to_value::text
|
||||
INTO manual_partition, manual_partition_from_value_text, manual_partition_to_value_text
|
||||
FROM pg_catalog.time_partitions tp
|
||||
WHERE
|
||||
((current_range_from_value::timestamptz >= tp.from_value::timestamptz AND current_range_from_value < tp.to_value::timestamptz) OR
|
||||
(current_range_to_value::timestamptz > tp.from_value::timestamptz AND current_range_to_value::timestamptz < tp.to_value::timestamptz)) AND
|
||||
parent_table = table_name;
|
||||
|
||||
IF found THEN
|
||||
RAISE 'partition % with the range from % to % does not align with the initial partition given the partition interval',
|
||||
manual_partition::text,
|
||||
manual_partition_from_value_text,
|
||||
manual_partition_to_value_text
|
||||
USING HINT = 'Only use partitions of the same size, without gaps between partitions.';
|
||||
END IF;
|
||||
|
||||
IF partition_column_type = 'date'::regtype 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;
|
||||
ELSIF partition_column_type = 'timestamp without time zone'::regtype 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;
|
||||
ELSIF partition_column_type = 'timestamp with time zone'::regtype 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;
|
||||
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
|
||||
RETURN QUERY
|
||||
SELECT
|
||||
substring(table_name_text, 0, max_table_name_length - length(to_char(current_range_from_value, partition_name_format)) - 1) || '_p' ||
|
||||
to_char(current_range_from_value, partition_name_format),
|
||||
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 + partition_interval;
|
||||
END LOOP;
|
||||
RETURN;
|
||||
END;
|
||||
$$;
|
||||
COMMENT ON FUNCTION pg_catalog.get_missing_time_partition_ranges(
|
||||
table_name regclass,
|
||||
partition_interval INTERVAL,
|
||||
to_value timestamptz,
|
||||
from_value timestamptz)
|
||||
IS 'get missing partitions ranges for table within the range using the given interval';
|
|
@ -0,0 +1,219 @@
|
|||
CREATE OR REPLACE FUNCTION pg_catalog.get_missing_time_partition_ranges(
|
||||
table_name regclass,
|
||||
partition_interval INTERVAL,
|
||||
to_value timestamptz,
|
||||
from_value timestamptz DEFAULT now())
|
||||
returns table(
|
||||
partition_name text,
|
||||
range_from_value text,
|
||||
range_to_value text)
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
DECLARE
|
||||
-- properties of the partitioned table
|
||||
table_name_text text;
|
||||
table_schema_text text;
|
||||
number_of_partition_columns int;
|
||||
partition_column_index int;
|
||||
partition_column_type regtype;
|
||||
|
||||
-- used for generating time ranges
|
||||
current_range_from_value timestamptz := NULL;
|
||||
current_range_to_value timestamptz := NULL;
|
||||
current_range_from_value_text text;
|
||||
current_range_to_value_text text;
|
||||
|
||||
-- used to check whether there are misaligned (manually created) partitions
|
||||
manual_partition regclass;
|
||||
manual_partition_from_value_text text;
|
||||
manual_partition_to_value_text text;
|
||||
|
||||
-- used for partition naming
|
||||
partition_name_format text;
|
||||
max_table_name_length int := current_setting('max_identifier_length');
|
||||
|
||||
-- used to determine whether the partition_interval is a day multiple
|
||||
is_day_multiple boolean;
|
||||
BEGIN
|
||||
-- check whether the table is time partitioned table, if not error out
|
||||
SELECT relname, nspname, partnatts, partattrs[0]
|
||||
INTO table_name_text, table_schema_text, number_of_partition_columns, partition_column_index
|
||||
FROM pg_catalog.pg_partitioned_table, pg_catalog.pg_class c, pg_catalog.pg_namespace n
|
||||
WHERE partrelid = c.oid AND c.oid = table_name
|
||||
AND c.relnamespace = n.oid;
|
||||
IF NOT FOUND THEN
|
||||
RAISE '% is not partitioned', table_name;
|
||||
ELSIF number_of_partition_columns <> 1 THEN
|
||||
RAISE 'partitioned tables with multiple partition columns are not supported';
|
||||
END IF;
|
||||
|
||||
-- to not to have partitions to be created in parallel
|
||||
EXECUTE format('LOCK TABLE %I.%I IN SHARE UPDATE EXCLUSIVE MODE', table_schema_text, table_name_text);
|
||||
|
||||
-- get datatype here to check interval-table type alignment and generate range values in the right data format
|
||||
SELECT atttypid
|
||||
INTO partition_column_type
|
||||
FROM pg_attribute
|
||||
WHERE attrelid = table_name::oid
|
||||
AND attnum = partition_column_index;
|
||||
|
||||
-- we currently only support partitioning by date, timestamp, and timestamptz
|
||||
IF partition_column_type <> 'date'::regtype
|
||||
AND partition_column_type <> 'timestamp'::regtype
|
||||
AND partition_column_type <> 'timestamptz'::regtype THEN
|
||||
RAISE 'type of the partition column of the table % must be date, timestamp or timestamptz', table_name;
|
||||
END IF;
|
||||
|
||||
IF partition_column_type = 'date'::regtype AND partition_interval IS NOT NULL THEN
|
||||
SELECT date_trunc('day', partition_interval) = partition_interval
|
||||
INTO is_day_multiple;
|
||||
|
||||
IF NOT is_day_multiple THEN
|
||||
RAISE 'partition interval of date partitioned table must be day or multiple days';
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
-- If no partition exists, truncate from_value to find intuitive initial value.
|
||||
-- If any partition exist, use the initial partition as the pivot partition.
|
||||
-- tp.to_value and tp.from_value are equal to '', if default partition exists.
|
||||
SELECT tp.from_value::timestamptz, tp.to_value::timestamptz
|
||||
INTO current_range_from_value, current_range_to_value
|
||||
FROM pg_catalog.time_partitions tp
|
||||
WHERE parent_table = table_name AND tp.to_value <> '' AND tp.from_value <> ''
|
||||
ORDER BY tp.from_value::timestamptz ASC
|
||||
LIMIT 1;
|
||||
|
||||
IF NOT FOUND THEN
|
||||
-- Decide on the current_range_from_value of the initial partition according to interval of the table.
|
||||
-- Since we will create all other partitions by adding intervals, truncating given start time will provide
|
||||
-- more intuitive interval ranges, instead of starting from from_value directly.
|
||||
IF partition_interval < INTERVAL '1 hour' THEN
|
||||
current_range_from_value = date_trunc('minute', from_value);
|
||||
ELSIF partition_interval < INTERVAL '1 day' THEN
|
||||
current_range_from_value = date_trunc('hour', from_value);
|
||||
ELSIF partition_interval < INTERVAL '1 week' THEN
|
||||
current_range_from_value = date_trunc('day', from_value);
|
||||
ELSIF partition_interval < INTERVAL '1 month' THEN
|
||||
current_range_from_value = date_trunc('week', from_value);
|
||||
ELSIF partition_interval = INTERVAL '3 months' THEN
|
||||
current_range_from_value = date_trunc('quarter', from_value);
|
||||
ELSIF partition_interval < INTERVAL '1 year' THEN
|
||||
current_range_from_value = date_trunc('month', from_value);
|
||||
ELSE
|
||||
current_range_from_value = date_trunc('year', from_value);
|
||||
END IF;
|
||||
|
||||
current_range_to_value := current_range_from_value + partition_interval;
|
||||
ELSE
|
||||
-- if from_value is newer than pivot's from value, go forward, else go backward
|
||||
IF from_value >= current_range_from_value THEN
|
||||
WHILE current_range_from_value < from_value LOOP
|
||||
current_range_from_value := current_range_from_value + partition_interval;
|
||||
END LOOP;
|
||||
ELSE
|
||||
WHILE current_range_from_value > from_value LOOP
|
||||
current_range_from_value := current_range_from_value - partition_interval;
|
||||
END LOOP;
|
||||
END IF;
|
||||
current_range_to_value := current_range_from_value + partition_interval;
|
||||
END IF;
|
||||
|
||||
-- reuse pg_partman naming scheme for back-and-forth migration
|
||||
IF partition_interval = INTERVAL '3 months' THEN
|
||||
-- include quarter in partition name
|
||||
partition_name_format = 'YYYY"q"Q';
|
||||
ELSIF partition_interval = INTERVAL '1 week' THEN
|
||||
-- include week number in partition name
|
||||
partition_name_format := 'IYYY"w"IW';
|
||||
ELSE
|
||||
-- always start with the year
|
||||
partition_name_format := 'YYYY';
|
||||
|
||||
IF partition_interval < INTERVAL '1 year' THEN
|
||||
-- include month in partition name
|
||||
partition_name_format := partition_name_format || '_MM';
|
||||
END IF;
|
||||
|
||||
IF partition_interval < INTERVAL '1 month' THEN
|
||||
-- include day of month in partition name
|
||||
partition_name_format := partition_name_format || '_DD';
|
||||
END IF;
|
||||
|
||||
IF partition_interval < INTERVAL '1 day' THEN
|
||||
-- include time of day in partition name
|
||||
partition_name_format := partition_name_format || '_HH24MI';
|
||||
END IF;
|
||||
|
||||
IF partition_interval < INTERVAL '1 minute' THEN
|
||||
-- include seconds in time of day in partition name
|
||||
partition_name_format := partition_name_format || 'SS';
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
WHILE current_range_from_value < to_value LOOP
|
||||
-- Check whether partition with given range has already been created
|
||||
-- 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 tp
|
||||
WHERE
|
||||
tp.from_value::timestamptz = current_range_from_value::timestamptz AND
|
||||
tp.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 + partition_interval;
|
||||
CONTINUE;
|
||||
END IF;
|
||||
|
||||
-- Check whether any other partition covers from_value or to_value
|
||||
-- That means some partitions doesn't align with the initial partition.
|
||||
-- In other words, gap(s) exist between partitions which is not multiple of intervals.
|
||||
SELECT partition, tp.from_value::text, tp.to_value::text
|
||||
INTO manual_partition, manual_partition_from_value_text, manual_partition_to_value_text
|
||||
FROM pg_catalog.time_partitions tp
|
||||
WHERE
|
||||
((current_range_from_value::timestamptz >= tp.from_value::timestamptz AND current_range_from_value < tp.to_value::timestamptz) OR
|
||||
(current_range_to_value::timestamptz > tp.from_value::timestamptz AND current_range_to_value::timestamptz < tp.to_value::timestamptz)) AND
|
||||
parent_table = table_name;
|
||||
|
||||
IF found THEN
|
||||
RAISE 'partition % with the range from % to % does not align with the initial partition given the partition interval',
|
||||
manual_partition::text,
|
||||
manual_partition_from_value_text,
|
||||
manual_partition_to_value_text
|
||||
USING HINT = 'Only use partitions of the same size, without gaps between partitions.';
|
||||
END IF;
|
||||
|
||||
IF partition_column_type = 'date'::regtype 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;
|
||||
ELSIF partition_column_type = 'timestamp without time zone'::regtype 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;
|
||||
ELSIF partition_column_type = 'timestamp with time zone'::regtype 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;
|
||||
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
|
||||
RETURN QUERY
|
||||
SELECT
|
||||
substring(table_name_text, 0, max_table_name_length - length(to_char(current_range_from_value, partition_name_format)) - 1) || '_p' ||
|
||||
to_char(current_range_from_value, partition_name_format),
|
||||
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 + partition_interval;
|
||||
END LOOP;
|
||||
RETURN;
|
||||
END;
|
||||
$$;
|
||||
COMMENT ON FUNCTION pg_catalog.get_missing_time_partition_ranges(
|
||||
table_name regclass,
|
||||
partition_interval INTERVAL,
|
||||
to_value timestamptz,
|
||||
from_value timestamptz)
|
||||
IS 'get missing partitions ranges for table within the range using the given interval';
|
|
@ -229,6 +229,7 @@ s/ERROR: parallel workers for vacuum must/ERROR: parallel vacuum degree must/g
|
|||
|
||||
# ignore PL/pgSQL line numbers that differ on Mac builds
|
||||
s/(CONTEXT: PL\/pgSQL function .* line )([0-9]+)/\1XX/g
|
||||
s/^(PL\/pgSQL function .* line) [0-9]+ (.*)/\1 XX \2/g
|
||||
|
||||
# can be removed after dropping PG13 support
|
||||
s/ERROR: parallel workers for vacuum must be between/ERROR: parallel vacuum degree must be between/g
|
||||
|
|
|
@ -231,10 +231,10 @@ $$ LANGUAGE plpgsql;
|
|||
SELECT modify_fast_path_plpsql(1,1);
|
||||
DEBUG: Deferred pruning for a fast-path router query
|
||||
CONTEXT: SQL statement "DELETE FROM modify_fast_path WHERE key = $1 AND value_1 = $2"
|
||||
PL/pgSQL function modify_fast_path_plpsql(integer,integer) line 3 at SQL statement
|
||||
PL/pgSQL function modify_fast_path_plpsql(integer,integer) line XX at SQL statement
|
||||
DEBUG: Creating router plan
|
||||
CONTEXT: SQL statement "DELETE FROM modify_fast_path WHERE key = $1 AND value_1 = $2"
|
||||
PL/pgSQL function modify_fast_path_plpsql(integer,integer) line 3 at SQL statement
|
||||
PL/pgSQL function modify_fast_path_plpsql(integer,integer) line XX at SQL statement
|
||||
modify_fast_path_plpsql
|
||||
---------------------------------------------------------------------
|
||||
|
||||
|
@ -243,10 +243,10 @@ PL/pgSQL function modify_fast_path_plpsql(integer,integer) line 3 at SQL stateme
|
|||
SELECT modify_fast_path_plpsql(2,2);
|
||||
DEBUG: Deferred pruning for a fast-path router query
|
||||
CONTEXT: SQL statement "DELETE FROM modify_fast_path WHERE key = $1 AND value_1 = $2"
|
||||
PL/pgSQL function modify_fast_path_plpsql(integer,integer) line 3 at SQL statement
|
||||
PL/pgSQL function modify_fast_path_plpsql(integer,integer) line XX at SQL statement
|
||||
DEBUG: Creating router plan
|
||||
CONTEXT: SQL statement "DELETE FROM modify_fast_path WHERE key = $1 AND value_1 = $2"
|
||||
PL/pgSQL function modify_fast_path_plpsql(integer,integer) line 3 at SQL statement
|
||||
PL/pgSQL function modify_fast_path_plpsql(integer,integer) line XX at SQL statement
|
||||
modify_fast_path_plpsql
|
||||
---------------------------------------------------------------------
|
||||
|
||||
|
@ -255,10 +255,10 @@ PL/pgSQL function modify_fast_path_plpsql(integer,integer) line 3 at SQL stateme
|
|||
SELECT modify_fast_path_plpsql(3,3);
|
||||
DEBUG: Deferred pruning for a fast-path router query
|
||||
CONTEXT: SQL statement "DELETE FROM modify_fast_path WHERE key = $1 AND value_1 = $2"
|
||||
PL/pgSQL function modify_fast_path_plpsql(integer,integer) line 3 at SQL statement
|
||||
PL/pgSQL function modify_fast_path_plpsql(integer,integer) line XX at SQL statement
|
||||
DEBUG: Creating router plan
|
||||
CONTEXT: SQL statement "DELETE FROM modify_fast_path WHERE key = $1 AND value_1 = $2"
|
||||
PL/pgSQL function modify_fast_path_plpsql(integer,integer) line 3 at SQL statement
|
||||
PL/pgSQL function modify_fast_path_plpsql(integer,integer) line XX at SQL statement
|
||||
modify_fast_path_plpsql
|
||||
---------------------------------------------------------------------
|
||||
|
||||
|
@ -267,10 +267,10 @@ PL/pgSQL function modify_fast_path_plpsql(integer,integer) line 3 at SQL stateme
|
|||
SELECT modify_fast_path_plpsql(4,4);
|
||||
DEBUG: Deferred pruning for a fast-path router query
|
||||
CONTEXT: SQL statement "DELETE FROM modify_fast_path WHERE key = $1 AND value_1 = $2"
|
||||
PL/pgSQL function modify_fast_path_plpsql(integer,integer) line 3 at SQL statement
|
||||
PL/pgSQL function modify_fast_path_plpsql(integer,integer) line XX at SQL statement
|
||||
DEBUG: Creating router plan
|
||||
CONTEXT: SQL statement "DELETE FROM modify_fast_path WHERE key = $1 AND value_1 = $2"
|
||||
PL/pgSQL function modify_fast_path_plpsql(integer,integer) line 3 at SQL statement
|
||||
PL/pgSQL function modify_fast_path_plpsql(integer,integer) line XX at SQL statement
|
||||
modify_fast_path_plpsql
|
||||
---------------------------------------------------------------------
|
||||
|
||||
|
@ -279,10 +279,10 @@ PL/pgSQL function modify_fast_path_plpsql(integer,integer) line 3 at SQL stateme
|
|||
SELECT modify_fast_path_plpsql(5,5);
|
||||
DEBUG: Deferred pruning for a fast-path router query
|
||||
CONTEXT: SQL statement "DELETE FROM modify_fast_path WHERE key = $1 AND value_1 = $2"
|
||||
PL/pgSQL function modify_fast_path_plpsql(integer,integer) line 3 at SQL statement
|
||||
PL/pgSQL function modify_fast_path_plpsql(integer,integer) line XX at SQL statement
|
||||
DEBUG: Creating router plan
|
||||
CONTEXT: SQL statement "DELETE FROM modify_fast_path WHERE key = $1 AND value_1 = $2"
|
||||
PL/pgSQL function modify_fast_path_plpsql(integer,integer) line 3 at SQL statement
|
||||
PL/pgSQL function modify_fast_path_plpsql(integer,integer) line XX at SQL statement
|
||||
modify_fast_path_plpsql
|
||||
---------------------------------------------------------------------
|
||||
|
||||
|
@ -291,10 +291,10 @@ PL/pgSQL function modify_fast_path_plpsql(integer,integer) line 3 at SQL stateme
|
|||
SELECT modify_fast_path_plpsql(6,6);
|
||||
DEBUG: Deferred pruning for a fast-path router query
|
||||
CONTEXT: SQL statement "DELETE FROM modify_fast_path WHERE key = $1 AND value_1 = $2"
|
||||
PL/pgSQL function modify_fast_path_plpsql(integer,integer) line 3 at SQL statement
|
||||
PL/pgSQL function modify_fast_path_plpsql(integer,integer) line XX at SQL statement
|
||||
DEBUG: Creating router plan
|
||||
CONTEXT: SQL statement "DELETE FROM modify_fast_path WHERE key = $1 AND value_1 = $2"
|
||||
PL/pgSQL function modify_fast_path_plpsql(integer,integer) line 3 at SQL statement
|
||||
PL/pgSQL function modify_fast_path_plpsql(integer,integer) line XX at SQL statement
|
||||
modify_fast_path_plpsql
|
||||
---------------------------------------------------------------------
|
||||
|
||||
|
|
|
@ -12,7 +12,7 @@ SELECT run_command_on_coordinator_and_workers('CREATE USER role_1');
|
|||
NOTICE: not propagating CREATE ROLE/USER commands to worker nodes
|
||||
HINT: Connect to worker nodes directly to manually create all necessary users and roles.
|
||||
CONTEXT: SQL statement "CREATE USER role_1"
|
||||
PL/pgSQL function run_command_on_coordinator_and_workers(text) line 3 at EXECUTE
|
||||
PL/pgSQL function run_command_on_coordinator_and_workers(text) line XX at EXECUTE
|
||||
run_command_on_coordinator_and_workers
|
||||
---------------------------------------------------------------------
|
||||
|
||||
|
@ -22,7 +22,7 @@ SELECT run_command_on_coordinator_and_workers('CREATE USER role_2');
|
|||
NOTICE: not propagating CREATE ROLE/USER commands to worker nodes
|
||||
HINT: Connect to worker nodes directly to manually create all necessary users and roles.
|
||||
CONTEXT: SQL statement "CREATE USER role_2"
|
||||
PL/pgSQL function run_command_on_coordinator_and_workers(text) line 3 at EXECUTE
|
||||
PL/pgSQL function run_command_on_coordinator_and_workers(text) line XX at EXECUTE
|
||||
run_command_on_coordinator_and_workers
|
||||
---------------------------------------------------------------------
|
||||
|
||||
|
@ -32,7 +32,7 @@ SELECT run_command_on_coordinator_and_workers('CREATE USER role_3');
|
|||
NOTICE: not propagating CREATE ROLE/USER commands to worker nodes
|
||||
HINT: Connect to worker nodes directly to manually create all necessary users and roles.
|
||||
CONTEXT: SQL statement "CREATE USER role_3"
|
||||
PL/pgSQL function run_command_on_coordinator_and_workers(text) line 3 at EXECUTE
|
||||
PL/pgSQL function run_command_on_coordinator_and_workers(text) line XX at EXECUTE
|
||||
run_command_on_coordinator_and_workers
|
||||
---------------------------------------------------------------------
|
||||
|
||||
|
|
|
@ -810,13 +810,13 @@ $$ LANGUAGE plpgsql;
|
|||
CALL only_local_execution();
|
||||
NOTICE: executing the command locally: INSERT INTO local_shard_execution.distributed_table_1470001 AS citus_table_alias (key, value, age) VALUES (1, '11'::text, 21) ON CONFLICT(key) DO UPDATE SET value = '29'::text
|
||||
CONTEXT: SQL statement "INSERT INTO distributed_table VALUES (1, '11',21) ON CONFLICT(key) DO UPDATE SET value = '29'"
|
||||
PL/pgSQL function only_local_execution() line 4 at SQL statement
|
||||
PL/pgSQL function only_local_execution() line XX at SQL statement
|
||||
NOTICE: executing the command locally: SELECT count(*) AS count FROM local_shard_execution.distributed_table_1470001 distributed_table WHERE (key OPERATOR(pg_catalog.=) 1)
|
||||
CONTEXT: SQL statement "SELECT count(*) FROM distributed_table WHERE key = 1"
|
||||
PL/pgSQL function only_local_execution() line 5 at SQL statement
|
||||
PL/pgSQL function only_local_execution() line XX at SQL statement
|
||||
NOTICE: executing the command locally: DELETE FROM local_shard_execution.distributed_table_1470001 distributed_table WHERE (key OPERATOR(pg_catalog.=) 1)
|
||||
CONTEXT: SQL statement "DELETE FROM distributed_table WHERE key = 1"
|
||||
PL/pgSQL function only_local_execution() line 6 at SQL statement
|
||||
PL/pgSQL function only_local_execution() line XX at SQL statement
|
||||
-- insert a row that we need in the next tests
|
||||
INSERT INTO distributed_table VALUES (1, '11',21) ON CONFLICT(key) DO UPDATE SET value = '29';
|
||||
NOTICE: executing the command locally: INSERT INTO local_shard_execution.distributed_table_1470001 AS citus_table_alias (key, value, age) VALUES (1, '11'::text, 21) ON CONFLICT(key) DO UPDATE SET value = '29'::text
|
||||
|
@ -840,10 +840,10 @@ $$ LANGUAGE plpgsql;
|
|||
CALL only_local_execution_with_function_evaluation();
|
||||
NOTICE: executing the command locally: SELECT local_shard_execution.get_local_node_id_volatile() AS get_local_node_id_volatile FROM local_shard_execution.distributed_table_1470001 distributed_table WHERE (key OPERATOR(pg_catalog.=) 1)
|
||||
CONTEXT: SQL statement "SELECT get_local_node_id_volatile() FROM distributed_table WHERE key = 1"
|
||||
PL/pgSQL function only_local_execution_with_function_evaluation() line 5 at SQL statement
|
||||
PL/pgSQL function only_local_execution_with_function_evaluation() line XX at SQL statement
|
||||
NOTICE: executing the command locally: SELECT local_shard_execution.get_local_node_id_volatile() AS get_local_node_id_volatile FROM (local_shard_execution.distributed_table_1470001 d1(key, value, age) JOIN local_shard_execution.distributed_table_1470001 d2(key, value, age) USING (key)) WHERE (d1.key OPERATOR(pg_catalog.=) 1)
|
||||
CONTEXT: SQL statement "SELECT get_local_node_id_volatile() FROM distributed_table d1 JOIN distributed_table d2 USING (key) WHERE d1.key = 1"
|
||||
PL/pgSQL function only_local_execution_with_function_evaluation() line 11 at SQL statement
|
||||
PL/pgSQL function only_local_execution_with_function_evaluation() line XX at SQL statement
|
||||
CREATE OR REPLACE PROCEDURE only_local_execution_with_params(int) AS $$
|
||||
DECLARE cnt INT;
|
||||
BEGIN
|
||||
|
@ -855,13 +855,13 @@ $$ LANGUAGE plpgsql;
|
|||
CALL only_local_execution_with_params(1);
|
||||
NOTICE: executing the command locally: INSERT INTO local_shard_execution.distributed_table_1470001 AS citus_table_alias (key, value, age) VALUES (1, '11'::text, '21'::bigint) ON CONFLICT(key) DO UPDATE SET value = '29'::text
|
||||
CONTEXT: SQL statement "INSERT INTO distributed_table VALUES ($1, '11',21) ON CONFLICT(key) DO UPDATE SET value = '29'"
|
||||
PL/pgSQL function only_local_execution_with_params(integer) line 4 at SQL statement
|
||||
PL/pgSQL function only_local_execution_with_params(integer) line XX at SQL statement
|
||||
NOTICE: executing the command locally: SELECT count(*) AS count FROM local_shard_execution.distributed_table_1470001 distributed_table WHERE (key OPERATOR(pg_catalog.=) 1)
|
||||
CONTEXT: SQL statement "SELECT count(*) FROM distributed_table WHERE key = $1"
|
||||
PL/pgSQL function only_local_execution_with_params(integer) line 5 at SQL statement
|
||||
PL/pgSQL function only_local_execution_with_params(integer) line XX at SQL statement
|
||||
NOTICE: executing the command locally: DELETE FROM local_shard_execution.distributed_table_1470001 distributed_table WHERE (key OPERATOR(pg_catalog.=) 1)
|
||||
CONTEXT: SQL statement "DELETE FROM distributed_table WHERE key = $1"
|
||||
PL/pgSQL function only_local_execution_with_params(integer) line 6 at SQL statement
|
||||
PL/pgSQL function only_local_execution_with_params(integer) line XX at SQL statement
|
||||
CREATE OR REPLACE PROCEDURE only_local_execution_with_function_evaluation_param(int) AS $$
|
||||
DECLARE nodeId INT;
|
||||
BEGIN
|
||||
|
@ -881,10 +881,10 @@ $$ LANGUAGE plpgsql;
|
|||
CALL only_local_execution_with_function_evaluation_param(1);
|
||||
NOTICE: executing the command locally: SELECT local_shard_execution.get_local_node_id_volatile() AS get_local_node_id_volatile FROM local_shard_execution.distributed_table_1470001 distributed_table WHERE (key OPERATOR(pg_catalog.=) 1)
|
||||
CONTEXT: SQL statement "SELECT get_local_node_id_volatile() FROM distributed_table WHERE key = $1"
|
||||
PL/pgSQL function only_local_execution_with_function_evaluation_param(integer) line 5 at SQL statement
|
||||
PL/pgSQL function only_local_execution_with_function_evaluation_param(integer) line XX at SQL statement
|
||||
NOTICE: executing the command locally: SELECT local_shard_execution.get_local_node_id_volatile() AS get_local_node_id_volatile FROM (local_shard_execution.distributed_table_1470001 d1(key, value, age) JOIN local_shard_execution.distributed_table_1470001 d2(key, value, age) USING (key)) WHERE (d1.key OPERATOR(pg_catalog.=) $1)
|
||||
CONTEXT: SQL statement "SELECT get_local_node_id_volatile() FROM distributed_table d1 JOIN distributed_table d2 USING (key) WHERE d1.key = $1"
|
||||
PL/pgSQL function only_local_execution_with_function_evaluation_param(integer) line 11 at SQL statement
|
||||
PL/pgSQL function only_local_execution_with_function_evaluation_param(integer) line XX at SQL statement
|
||||
CREATE OR REPLACE PROCEDURE local_execution_followed_by_dist() AS $$
|
||||
DECLARE cnt INT;
|
||||
BEGIN
|
||||
|
@ -897,22 +897,22 @@ $$ LANGUAGE plpgsql;
|
|||
CALL local_execution_followed_by_dist();
|
||||
NOTICE: executing the command locally: INSERT INTO local_shard_execution.distributed_table_1470001 AS citus_table_alias (key, value, age) VALUES (1, '11'::text, 21) ON CONFLICT(key) DO UPDATE SET value = '29'::text
|
||||
CONTEXT: SQL statement "INSERT INTO distributed_table VALUES (1, '11',21) ON CONFLICT(key) DO UPDATE SET value = '29'"
|
||||
PL/pgSQL function local_execution_followed_by_dist() line 4 at SQL statement
|
||||
PL/pgSQL function local_execution_followed_by_dist() line XX at SQL statement
|
||||
NOTICE: executing the command locally: SELECT count(*) AS count FROM local_shard_execution.distributed_table_1470001 distributed_table WHERE (key OPERATOR(pg_catalog.=) 1)
|
||||
CONTEXT: SQL statement "SELECT count(*) FROM distributed_table WHERE key = 1"
|
||||
PL/pgSQL function local_execution_followed_by_dist() line 5 at SQL statement
|
||||
PL/pgSQL function local_execution_followed_by_dist() line XX at SQL statement
|
||||
NOTICE: executing the command locally: DELETE FROM local_shard_execution.distributed_table_1470001 distributed_table
|
||||
CONTEXT: SQL statement "DELETE FROM distributed_table"
|
||||
PL/pgSQL function local_execution_followed_by_dist() line 6 at SQL statement
|
||||
PL/pgSQL function local_execution_followed_by_dist() line XX at SQL statement
|
||||
NOTICE: executing the command locally: DELETE FROM local_shard_execution.distributed_table_1470003 distributed_table
|
||||
CONTEXT: SQL statement "DELETE FROM distributed_table"
|
||||
PL/pgSQL function local_execution_followed_by_dist() line 6 at SQL statement
|
||||
PL/pgSQL function local_execution_followed_by_dist() line XX at SQL statement
|
||||
NOTICE: executing the command locally: SELECT count(*) AS count FROM local_shard_execution.distributed_table_1470001 distributed_table WHERE true
|
||||
CONTEXT: SQL statement "SELECT count(*) FROM distributed_table"
|
||||
PL/pgSQL function local_execution_followed_by_dist() line 7 at SQL statement
|
||||
PL/pgSQL function local_execution_followed_by_dist() line XX at SQL statement
|
||||
NOTICE: executing the command locally: SELECT count(*) AS count FROM local_shard_execution.distributed_table_1470003 distributed_table WHERE true
|
||||
CONTEXT: SQL statement "SELECT count(*) FROM distributed_table"
|
||||
PL/pgSQL function local_execution_followed_by_dist() line 7 at SQL statement
|
||||
PL/pgSQL function local_execution_followed_by_dist() line XX at SQL statement
|
||||
-- test CTEs, including modifying CTEs
|
||||
WITH local_insert AS (INSERT INTO distributed_table VALUES (1, '11',21) ON CONFLICT(key) DO UPDATE SET value = '29' RETURNING *),
|
||||
distributed_local_mixed AS (SELECT * FROM reference_table WHERE key IN (SELECT key FROM local_insert))
|
||||
|
|
|
@ -806,8 +806,11 @@ SELECT * FROM multi_extension.print_extension_changes();
|
|||
| function citus_internal_delete_shard_metadata(bigint) void
|
||||
| function citus_internal_update_placement_metadata(bigint,integer,integer) void
|
||||
| function citus_internal_update_relation_colocation(oid,integer) void
|
||||
| function create_time_partitions(regclass,interval,timestamp with time zone,timestamp with time zone) boolean
|
||||
| function drop_old_time_partitions(regclass,timestamp with time zone)
|
||||
| function get_missing_time_partition_ranges(regclass,interval,timestamp with time zone,timestamp with time zone) TABLE(partition_name text, range_from_value text, range_to_value text)
|
||||
| function stop_metadata_sync_to_node(text,integer,boolean) void
|
||||
(12 rows)
|
||||
(15 rows)
|
||||
|
||||
DROP TABLE multi_extension.prev_objects, multi_extension.extension_diff;
|
||||
-- show running version
|
||||
|
|
|
@ -183,10 +183,10 @@ call multi_mx_call.mx_call_proc(2, 0);
|
|||
DEBUG: stored procedure does not have co-located tables
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_call.mx_call_dist_table_1 t1 JOIN multi_mx_call.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT ((3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint))))::integer
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
y
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -267,10 +267,10 @@ call multi_mx_call.mx_call_proc(2, 0);
|
|||
DEBUG: cannot push down CALL in multi-statement transaction
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_call.mx_call_dist_table_1 t1 JOIN multi_mx_call.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT ((3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint))))::integer
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
y
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -301,10 +301,10 @@ call multi_mx_call.mx_call_proc(2, 0);
|
|||
DEBUG: cannot push down invalid distribution_argument_index
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_call.mx_call_dist_table_1 t1 JOIN multi_mx_call.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT ((3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint))))::integer
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
y
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -320,10 +320,10 @@ call multi_mx_call.mx_call_proc(2, 0);
|
|||
DEBUG: cannot push down invalid distribution_argument_index
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_call.mx_call_dist_table_1 t1 JOIN multi_mx_call.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT ((3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint))))::integer
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
y
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -355,10 +355,10 @@ call multi_mx_call.mx_call_proc(2, 0);
|
|||
DEBUG: cannot push down function call for replicated distributed tables
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_call.mx_call_dist_table_1 t1 JOIN multi_mx_call.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT ((3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint))))::integer
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
y
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -450,10 +450,10 @@ call multi_mx_call.mx_call_proc(2, 0);
|
|||
DEBUG: there is no worker node with metadata
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_call.mx_call_dist_table_1 t1 JOIN multi_mx_call.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT ((3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint))))::integer
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
y
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -496,10 +496,10 @@ call multi_mx_call.mx_call_proc(2, mx_call_add(3, 4));
|
|||
DEBUG: distribution argument value must be a constant
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_call.mx_call_dist_table_1 t1 JOIN multi_mx_call.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT ((3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint))))::integer
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
y
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -518,10 +518,10 @@ call multi_mx_call.mx_call_proc(floor(random())::int, 2);
|
|||
DEBUG: arguments in a distributed stored procedure must be constant expressions
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_call.mx_call_dist_table_1 t1 JOIN multi_mx_call.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT ((1 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint))))::integer
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
y
|
||||
---------------------------------------------------------------------
|
||||
27
|
||||
|
|
|
@ -183,10 +183,10 @@ call multi_mx_call.mx_call_proc(2, 0);
|
|||
DEBUG: stored procedure does not have co-located tables
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_call.mx_call_dist_table_1 t1 JOIN multi_mx_call.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT (3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
y
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -267,10 +267,10 @@ call multi_mx_call.mx_call_proc(2, 0);
|
|||
DEBUG: cannot push down CALL in multi-statement transaction
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_call.mx_call_dist_table_1 t1 JOIN multi_mx_call.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT (3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
y
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -301,10 +301,10 @@ call multi_mx_call.mx_call_proc(2, 0);
|
|||
DEBUG: cannot push down invalid distribution_argument_index
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_call.mx_call_dist_table_1 t1 JOIN multi_mx_call.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT (3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
y
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -320,10 +320,10 @@ call multi_mx_call.mx_call_proc(2, 0);
|
|||
DEBUG: cannot push down invalid distribution_argument_index
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_call.mx_call_dist_table_1 t1 JOIN multi_mx_call.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT (3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
y
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -355,10 +355,10 @@ call multi_mx_call.mx_call_proc(2, 0);
|
|||
DEBUG: cannot push down function call for replicated distributed tables
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_call.mx_call_dist_table_1 t1 JOIN multi_mx_call.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT (3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
y
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -450,10 +450,10 @@ call multi_mx_call.mx_call_proc(2, 0);
|
|||
DEBUG: there is no worker node with metadata
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_call.mx_call_dist_table_1 t1 JOIN multi_mx_call.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT (3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
y
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -496,10 +496,10 @@ call multi_mx_call.mx_call_proc(2, mx_call_add(3, 4));
|
|||
DEBUG: distribution argument value must be a constant
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_call.mx_call_dist_table_1 t1 JOIN multi_mx_call.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT (3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
y
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -518,10 +518,10 @@ call multi_mx_call.mx_call_proc(floor(random())::int, 2);
|
|||
DEBUG: arguments in a distributed stored procedure must be constant expressions
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_call.mx_call_dist_table_1 t1 JOIN multi_mx_call.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT (1 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_call.mx_call_dist_table_1 t1 join multi_mx_call.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_proc(integer,integer) line XX at assignment
|
||||
y
|
||||
---------------------------------------------------------------------
|
||||
27
|
||||
|
|
|
@ -144,10 +144,10 @@ select mx_call_func(2, 0);
|
|||
DEBUG: function does not have co-located tables
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_function_call_delegation.mx_call_dist_table_1 t1 JOIN multi_mx_function_call_delegation.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT ((3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint))))::integer
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
mx_call_func
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -254,10 +254,10 @@ select mx_call_func(2, 0);
|
|||
DEBUG: not pushing down function calls in a multi-statement transaction
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_function_call_delegation.mx_call_dist_table_1 t1 JOIN multi_mx_function_call_delegation.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT ((3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint))))::integer
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
mx_call_func
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -288,10 +288,10 @@ select mx_call_func(2, 0);
|
|||
DEBUG: cannot push down invalid distribution_argument_index
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_function_call_delegation.mx_call_dist_table_1 t1 JOIN multi_mx_function_call_delegation.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT ((3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint))))::integer
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
mx_call_func
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -307,10 +307,10 @@ select mx_call_func(2, 0);
|
|||
DEBUG: cannot push down invalid distribution_argument_index
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_function_call_delegation.mx_call_dist_table_1 t1 JOIN multi_mx_function_call_delegation.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT ((3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint))))::integer
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
mx_call_func
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -341,10 +341,10 @@ select mx_call_func(2, 0);
|
|||
DEBUG: cannot push down function call for replicated distributed tables
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_function_call_delegation.mx_call_dist_table_1 t1 JOIN multi_mx_function_call_delegation.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT ((3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint))))::integer
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
mx_call_func
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -523,10 +523,10 @@ select mx_call_func(2, 0);
|
|||
DEBUG: the worker node does not have metadata
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_function_call_delegation.mx_call_dist_table_1 t1 JOIN multi_mx_function_call_delegation.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT ((3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint))))::integer
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
mx_call_func
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -570,10 +570,10 @@ select mx_call_func((select x + 1 from mx_call_add(3, 4) x), 2);
|
|||
DEBUG: arguments in a distributed function must not contain subqueries
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_function_call_delegation.mx_call_dist_table_1 t1 JOIN multi_mx_function_call_delegation.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT ((9 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint))))::integer
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
mx_call_func
|
||||
---------------------------------------------------------------------
|
||||
35
|
||||
|
@ -584,10 +584,10 @@ select mx_call_func(floor(random())::int, 2);
|
|||
DEBUG: arguments in a distributed function must be constant expressions
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_function_call_delegation.mx_call_dist_table_1 t1 JOIN multi_mx_function_call_delegation.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT ((1 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint))))::integer
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
mx_call_func
|
||||
---------------------------------------------------------------------
|
||||
27
|
||||
|
@ -597,10 +597,10 @@ PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
|||
select * from mx_call_func(2, 0);
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_function_call_delegation.mx_call_dist_table_1 t1 JOIN multi_mx_function_call_delegation.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT ((3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint))))::integer
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
y
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -623,10 +623,10 @@ select mx_call_func(2, 0) from mx_call_dist_table_1;
|
|||
select mx_call_func(2, 0) where mx_call_func(0, 2) = 0;
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_function_call_delegation.mx_call_dist_table_1 t1 JOIN multi_mx_function_call_delegation.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT ((1 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint))))::integer
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
mx_call_func
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
@ -634,16 +634,16 @@ PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
|||
select mx_call_func(2, 0), mx_call_func(0, 2);
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_function_call_delegation.mx_call_dist_table_1 t1 JOIN multi_mx_function_call_delegation.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT ((3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint))))::integer
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_function_call_delegation.mx_call_dist_table_1 t1 JOIN multi_mx_function_call_delegation.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT ((1 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint))))::integer
|
||||
CONTEXT: PL/pgSQL assignment "y := y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
mx_call_func | mx_call_func
|
||||
---------------------------------------------------------------------
|
||||
29 | 27
|
||||
|
@ -652,7 +652,7 @@ PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
|||
DO $$ BEGIN perform mx_call_func_tbl(40); END; $$;
|
||||
DEBUG: not pushing down function calls in a multi-statement transaction
|
||||
CONTEXT: SQL statement "SELECT mx_call_func_tbl(40)"
|
||||
PL/pgSQL function inline_code_block line 1 at PERFORM
|
||||
PL/pgSQL function inline_code_block line XX at PERFORM
|
||||
SELECT * FROM mx_call_dist_table_1 WHERE id >= 40 ORDER BY id, val;
|
||||
id | val
|
||||
---------------------------------------------------------------------
|
||||
|
|
|
@ -144,10 +144,10 @@ select mx_call_func(2, 0);
|
|||
DEBUG: function does not have co-located tables
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_function_call_delegation.mx_call_dist_table_1 t1 JOIN multi_mx_function_call_delegation.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT (3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
mx_call_func
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -246,10 +246,10 @@ select mx_call_func(2, 0);
|
|||
DEBUG: not pushing down function calls in a multi-statement transaction
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_function_call_delegation.mx_call_dist_table_1 t1 JOIN multi_mx_function_call_delegation.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT (3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
mx_call_func
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -280,10 +280,10 @@ select mx_call_func(2, 0);
|
|||
DEBUG: cannot push down invalid distribution_argument_index
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_function_call_delegation.mx_call_dist_table_1 t1 JOIN multi_mx_function_call_delegation.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT (3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
mx_call_func
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -299,10 +299,10 @@ select mx_call_func(2, 0);
|
|||
DEBUG: cannot push down invalid distribution_argument_index
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_function_call_delegation.mx_call_dist_table_1 t1 JOIN multi_mx_function_call_delegation.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT (3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
mx_call_func
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -333,10 +333,10 @@ select mx_call_func(2, 0);
|
|||
DEBUG: cannot push down function call for replicated distributed tables
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_function_call_delegation.mx_call_dist_table_1 t1 JOIN multi_mx_function_call_delegation.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT (3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
mx_call_func
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -515,10 +515,10 @@ select mx_call_func(2, 0);
|
|||
DEBUG: the worker node does not have metadata
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_function_call_delegation.mx_call_dist_table_1 t1 JOIN multi_mx_function_call_delegation.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT (3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
mx_call_func
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -562,10 +562,10 @@ select mx_call_func((select x + 1 from mx_call_add(3, 4) x), 2);
|
|||
DEBUG: arguments in a distributed function must not contain subqueries
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_function_call_delegation.mx_call_dist_table_1 t1 JOIN multi_mx_function_call_delegation.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT (9 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
mx_call_func
|
||||
---------------------------------------------------------------------
|
||||
35
|
||||
|
@ -576,10 +576,10 @@ select mx_call_func(floor(random())::int, 2);
|
|||
DEBUG: arguments in a distributed function must be constant expressions
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_function_call_delegation.mx_call_dist_table_1 t1 JOIN multi_mx_function_call_delegation.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT (1 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
mx_call_func
|
||||
---------------------------------------------------------------------
|
||||
27
|
||||
|
@ -589,10 +589,10 @@ PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
|||
select * from mx_call_func(2, 0);
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_function_call_delegation.mx_call_dist_table_1 t1 JOIN multi_mx_function_call_delegation.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT (3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
y
|
||||
---------------------------------------------------------------------
|
||||
29
|
||||
|
@ -615,10 +615,10 @@ select mx_call_func(2, 0) from mx_call_dist_table_1;
|
|||
select mx_call_func(2, 0) where mx_call_func(0, 2) = 0;
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_function_call_delegation.mx_call_dist_table_1 t1 JOIN multi_mx_function_call_delegation.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT (1 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
mx_call_func
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
@ -626,16 +626,16 @@ PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
|||
select mx_call_func(2, 0), mx_call_func(0, 2);
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_function_call_delegation.mx_call_dist_table_1 t1 JOIN multi_mx_function_call_delegation.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT (3 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
DEBUG: generating subplan XXX_1 for subquery SELECT sum((t1.val OPERATOR(pg_catalog.+) t2.val)) AS sum FROM (multi_mx_function_call_delegation.mx_call_dist_table_1 t1 JOIN multi_mx_function_call_delegation.mx_call_dist_table_2 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.id)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT (1 OPERATOR(pg_catalog.+) (SELECT intermediate_result.sum FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(sum bigint)))
|
||||
CONTEXT: SQL statement "SELECT y + (select sum(t1.val + t2.val) from multi_mx_function_call_delegation.mx_call_dist_table_1 t1 join multi_mx_function_call_delegation.mx_call_dist_table_2 t2 on t1.id = t2.id)"
|
||||
PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
||||
PL/pgSQL function mx_call_func(integer,integer) line XX at assignment
|
||||
mx_call_func | mx_call_func
|
||||
---------------------------------------------------------------------
|
||||
29 | 27
|
||||
|
@ -644,7 +644,7 @@ PL/pgSQL function mx_call_func(integer,integer) line 8 at assignment
|
|||
DO $$ BEGIN perform mx_call_func_tbl(40); END; $$;
|
||||
DEBUG: not pushing down function calls in a multi-statement transaction
|
||||
CONTEXT: SQL statement "SELECT mx_call_func_tbl(40)"
|
||||
PL/pgSQL function inline_code_block line 1 at PERFORM
|
||||
PL/pgSQL function inline_code_block line XX at PERFORM
|
||||
SELECT * FROM mx_call_dist_table_1 WHERE id >= 40 ORDER BY id, val;
|
||||
id | val
|
||||
---------------------------------------------------------------------
|
||||
|
|
|
@ -1377,11 +1377,11 @@ SELECT author_articles_max_id();
|
|||
DEBUG: Creating router plan
|
||||
CONTEXT: SQL statement "SELECT MAX(id) FROM articles_hash_mx ah
|
||||
WHERE author_id = 1"
|
||||
PL/pgSQL function author_articles_max_id() line 5 at SQL statement
|
||||
PL/pgSQL function author_articles_max_id() line XX at SQL statement
|
||||
DEBUG: query has a single distribution column value: 1
|
||||
CONTEXT: SQL statement "SELECT MAX(id) FROM articles_hash_mx ah
|
||||
WHERE author_id = 1"
|
||||
PL/pgSQL function author_articles_max_id() line 5 at SQL statement
|
||||
PL/pgSQL function author_articles_max_id() line XX at SQL statement
|
||||
author_articles_max_id
|
||||
---------------------------------------------------------------------
|
||||
41
|
||||
|
@ -1403,12 +1403,12 @@ DEBUG: Creating router plan
|
|||
CONTEXT: SQL statement "SELECT ah.id, ah.word_count
|
||||
FROM articles_hash_mx ah
|
||||
WHERE author_id = 1"
|
||||
PL/pgSQL function author_articles_id_word_count() line 4 at RETURN QUERY
|
||||
PL/pgSQL function author_articles_id_word_count() line XX at RETURN QUERY
|
||||
DEBUG: query has a single distribution column value: 1
|
||||
CONTEXT: SQL statement "SELECT ah.id, ah.word_count
|
||||
FROM articles_hash_mx ah
|
||||
WHERE author_id = 1"
|
||||
PL/pgSQL function author_articles_id_word_count() line 4 at RETURN QUERY
|
||||
PL/pgSQL function author_articles_id_word_count() line XX at RETURN QUERY
|
||||
id | word_count
|
||||
---------------------------------------------------------------------
|
||||
1 | 9572
|
||||
|
|
File diff suppressed because it is too large
Load Diff
|
@ -2303,11 +2303,11 @@ SELECT author_articles_max_id();
|
|||
DEBUG: Creating router plan
|
||||
CONTEXT: SQL statement "SELECT MAX(id) FROM articles_hash ah
|
||||
WHERE author_id = 1"
|
||||
PL/pgSQL function author_articles_max_id() line 5 at SQL statement
|
||||
PL/pgSQL function author_articles_max_id() line XX at SQL statement
|
||||
DEBUG: query has a single distribution column value: 1
|
||||
CONTEXT: SQL statement "SELECT MAX(id) FROM articles_hash ah
|
||||
WHERE author_id = 1"
|
||||
PL/pgSQL function author_articles_max_id() line 5 at SQL statement
|
||||
PL/pgSQL function author_articles_max_id() line XX at SQL statement
|
||||
author_articles_max_id
|
||||
---------------------------------------------------------------------
|
||||
41
|
||||
|
@ -2329,12 +2329,12 @@ DEBUG: Creating router plan
|
|||
CONTEXT: SQL statement "SELECT ah.id, ah.word_count
|
||||
FROM articles_hash ah
|
||||
WHERE author_id = 1"
|
||||
PL/pgSQL function author_articles_id_word_count() line 4 at RETURN QUERY
|
||||
PL/pgSQL function author_articles_id_word_count() line XX at RETURN QUERY
|
||||
DEBUG: query has a single distribution column value: 1
|
||||
CONTEXT: SQL statement "SELECT ah.id, ah.word_count
|
||||
FROM articles_hash ah
|
||||
WHERE author_id = 1"
|
||||
PL/pgSQL function author_articles_id_word_count() line 4 at RETURN QUERY
|
||||
PL/pgSQL function author_articles_id_word_count() line XX at RETURN QUERY
|
||||
id | word_count
|
||||
---------------------------------------------------------------------
|
||||
1 | 9572
|
||||
|
|
|
@ -1251,7 +1251,7 @@ SELECT run_command_on_coordinator_and_workers('CREATE USER "test-user"');
|
|||
NOTICE: not propagating CREATE ROLE/USER commands to worker nodes
|
||||
HINT: Connect to worker nodes directly to manually create all necessary users and roles.
|
||||
CONTEXT: SQL statement "CREATE USER "test-user""
|
||||
PL/pgSQL function run_command_on_coordinator_and_workers(text) line 3 at EXECUTE
|
||||
PL/pgSQL function run_command_on_coordinator_and_workers(text) line XX at EXECUTE
|
||||
run_command_on_coordinator_and_workers
|
||||
---------------------------------------------------------------------
|
||||
|
||||
|
|
|
@ -162,7 +162,7 @@ END;
|
|||
$$;
|
||||
NOTICE: executing the command locally: SELECT local_table.a, numbers.a FROM (replicate_ref_to_coordinator.local_table JOIN replicate_ref_to_coordinator.numbers_8000001 numbers(a) USING (a))
|
||||
CONTEXT: SQL statement "SELECT local_table.a, numbers.a FROM local_table NATURAL JOIN numbers"
|
||||
PL/pgSQL function inline_code_block line 3 at PERFORM
|
||||
PL/pgSQL function inline_code_block line XX at PERFORM
|
||||
-- test plpgsql function
|
||||
CREATE FUNCTION test_reference_local_join_plpgsql_func()
|
||||
RETURNS void AS $$
|
||||
|
@ -177,10 +177,10 @@ $$ LANGUAGE plpgsql;
|
|||
SELECT test_reference_local_join_plpgsql_func();
|
||||
NOTICE: executing the command locally: INSERT INTO replicate_ref_to_coordinator.numbers_8000001 (a) VALUES (4)
|
||||
CONTEXT: SQL statement "INSERT INTO numbers VALUES (4)"
|
||||
PL/pgSQL function test_reference_local_join_plpgsql_func() line 4 at SQL statement
|
||||
PL/pgSQL function test_reference_local_join_plpgsql_func() line XX at SQL statement
|
||||
NOTICE: executing the command locally: SELECT local_table.a, numbers.a FROM (replicate_ref_to_coordinator.local_table JOIN replicate_ref_to_coordinator.numbers_8000001 numbers(a) USING (a)) ORDER BY local_table.a
|
||||
CONTEXT: SQL statement "SELECT local_table.a, numbers.a FROM local_table NATURAL JOIN numbers ORDER BY 1"
|
||||
PL/pgSQL function test_reference_local_join_plpgsql_func() line 5 at PERFORM
|
||||
PL/pgSQL function test_reference_local_join_plpgsql_func() line XX at PERFORM
|
||||
ERROR:
|
||||
CONTEXT: PL/pgSQL function test_reference_local_join_plpgsql_func() line XX at RAISE
|
||||
SELECT sum(a) FROM local_table;
|
||||
|
|
|
@ -92,7 +92,7 @@ ERROR: duplicate key value violates unique constraint "idx_table_100503"
|
|||
DETAIL: Key (id, org_id)=(2, 12) already exists.
|
||||
CONTEXT: while executing command on localhost:xxxxx
|
||||
SQL statement "INSERT INTO test_table VALUES (tt_id, tt_org_id)"
|
||||
PL/pgSQL function test_procedure_modify_insert(integer,integer) line 5 at SQL statement
|
||||
PL/pgSQL function test_procedure_modify_insert(integer,integer) line XX at SQL statement
|
||||
SELECT * FROM test_table ORDER BY 1, 2;
|
||||
id | org_id
|
||||
---------------------------------------------------------------------
|
||||
|
@ -112,7 +112,7 @@ ERROR: duplicate key value violates unique constraint "idx_table_100503"
|
|||
DETAIL: Key (id, org_id)=(2, 30) already exists.
|
||||
CONTEXT: while executing command on localhost:xxxxx
|
||||
SQL statement "INSERT INTO test_table VALUES (tt_id, tt_org_id)"
|
||||
PL/pgSQL function test_procedure_modify_insert_commit(integer,integer) line 5 at SQL statement
|
||||
PL/pgSQL function test_procedure_modify_insert_commit(integer,integer) line XX at SQL statement
|
||||
SELECT * FROM test_table ORDER BY 1, 2;
|
||||
id | org_id
|
||||
---------------------------------------------------------------------
|
||||
|
|
|
@ -117,7 +117,9 @@ ORDER BY 1;
|
|||
function create_distributed_table(regclass,text,citus.distribution_type,text,integer)
|
||||
function create_intermediate_result(text,text)
|
||||
function create_reference_table(regclass)
|
||||
function create_time_partitions(regclass,interval,timestamp with time zone,timestamp with time zone)
|
||||
function distributed_tables_colocated(regclass,regclass)
|
||||
function drop_old_time_partitions(regclass,timestamp with time zone)
|
||||
function dump_global_wait_edges()
|
||||
function dump_local_wait_edges()
|
||||
function fetch_intermediate_results(text[],text,integer)
|
||||
|
@ -128,6 +130,7 @@ ORDER BY 1;
|
|||
function get_colocated_table_array(regclass)
|
||||
function get_current_transaction_id()
|
||||
function get_global_active_transactions()
|
||||
function get_missing_time_partition_ranges(regclass,interval,timestamp with time zone,timestamp with time zone)
|
||||
function get_rebalance_progress()
|
||||
function get_rebalance_table_shards_plan(regclass,real,integer,bigint[],boolean,name,real)
|
||||
function get_shard_id_for_distribution_column(regclass,"any")
|
||||
|
@ -254,5 +257,5 @@ ORDER BY 1;
|
|||
view citus_worker_stat_activity
|
||||
view pg_dist_shard_placement
|
||||
view time_partitions
|
||||
(238 rows)
|
||||
(241 rows)
|
||||
|
||||
|
|
|
@ -106,7 +106,9 @@ ORDER BY 1;
|
|||
function create_distributed_table(regclass,text,citus.distribution_type,text,integer)
|
||||
function create_intermediate_result(text,text)
|
||||
function create_reference_table(regclass)
|
||||
function create_time_partitions(regclass,interval,timestamp with time zone,timestamp with time zone)
|
||||
function distributed_tables_colocated(regclass,regclass)
|
||||
function drop_old_time_partitions(regclass,timestamp with time zone)
|
||||
function dump_global_wait_edges()
|
||||
function dump_local_wait_edges()
|
||||
function fetch_intermediate_results(text[],text,integer)
|
||||
|
@ -117,6 +119,7 @@ ORDER BY 1;
|
|||
function get_colocated_table_array(regclass)
|
||||
function get_current_transaction_id()
|
||||
function get_global_active_transactions()
|
||||
function get_missing_time_partition_ranges(regclass,interval,timestamp with time zone,timestamp with time zone)
|
||||
function get_rebalance_progress()
|
||||
function get_rebalance_table_shards_plan(regclass,real,integer,bigint[],boolean,name,real)
|
||||
function get_shard_id_for_distribution_column(regclass,"any")
|
||||
|
@ -240,5 +243,5 @@ ORDER BY 1;
|
|||
view citus_worker_stat_activity
|
||||
view pg_dist_shard_placement
|
||||
view time_partitions
|
||||
(224 rows)
|
||||
(227 rows)
|
||||
|
||||
|
|
|
@ -1280,6 +1280,583 @@ ALTER TABLE distributed_parent_table ATTACH PARTITION non_distributed_child_2 DE
|
|||
CREATE TABLE non_distributed_child_3 (event_id int NOT NULL, event_time timestamptz NOT NULL DEFAULT now());
|
||||
ALTER TABLE distributed_parent_table ATTACH PARTITION non_distributed_child_3 FOR VALUES FROM ('2021-07-30') TO ('2021-08-01');
|
||||
|
||||
-- Test time partition utility UDFs
|
||||
-- a) test get_missing_time_partition_ranges
|
||||
-- 1) test get_missing_time_partition_ranges with date partitioned table
|
||||
CREATE TABLE date_partitioned_table(
|
||||
measureid integer,
|
||||
eventdate date,
|
||||
measure_data jsonb) PARTITION BY RANGE(eventdate);
|
||||
|
||||
SELECT create_distributed_table('date_partitioned_table','measureid');
|
||||
|
||||
-- test interval must be multiple days for date partitioned table
|
||||
SELECT * FROM get_missing_time_partition_ranges('date_partitioned_table', INTERVAL '6 hours', '2022-01-01', '2021-01-01');
|
||||
SELECT * FROM get_missing_time_partition_ranges('date_partitioned_table', INTERVAL '1 week 1 day 1 hour', '2022-01-01', '2021-01-01');
|
||||
|
||||
-- test with various intervals
|
||||
SELECT * FROM get_missing_time_partition_ranges('date_partitioned_table', INTERVAL '1 day', '2021-02-01', '2021-01-01');
|
||||
SELECT * FROM get_missing_time_partition_ranges('date_partitioned_table', INTERVAL '1 week', '2022-01-01', '2021-01-01');
|
||||
SELECT * FROM get_missing_time_partition_ranges('date_partitioned_table', INTERVAL '1 month', '2022-01-01', '2021-01-01');
|
||||
SELECT * FROM get_missing_time_partition_ranges('date_partitioned_table', INTERVAL '3 months', '2022-01-01', '2021-01-01');
|
||||
SELECT * FROM get_missing_time_partition_ranges('date_partitioned_table', INTERVAL '6 months', '2022-01-01', '2021-01-01');
|
||||
|
||||
-- test with from_date > to_date
|
||||
SELECT * FROM get_missing_time_partition_ranges('date_partitioned_table', INTERVAL '1 day', '2021-01-01', '2021-02-01');
|
||||
|
||||
-- test with existing partitions
|
||||
BEGIN;
|
||||
CREATE TABLE date_partitioned_table_2021_01_01 PARTITION OF date_partitioned_table FOR VALUES FROM ('2021-01-01') TO ('2021-01-02');
|
||||
SELECT * FROM get_missing_time_partition_ranges('date_partitioned_table', INTERVAL '1 day', '2021-01-05', '2020-12-30');
|
||||
SELECT * FROM get_missing_time_partition_ranges('date_partitioned_table', INTERVAL '2 days', '2021-01-05', '2020-12-30');
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
CREATE TABLE date_partitioned_table_2021_01_01 PARTITION OF date_partitioned_table FOR VALUES FROM ('2021-01-01') TO ('2021-01-02');
|
||||
CREATE TABLE date_partitioned_table_2021_01_02 PARTITION OF date_partitioned_table FOR VALUES FROM ('2021-01-02') TO ('2021-01-03');
|
||||
SELECT * FROM get_missing_time_partition_ranges('date_partitioned_table', INTERVAL '1 day', '2021-01-05', '2020-12-30');
|
||||
SELECT * FROM get_missing_time_partition_ranges('date_partitioned_table', INTERVAL '2 days', '2021-01-05', '2020-12-30');
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
CREATE TABLE date_partitioned_table_2021_01_01 PARTITION OF date_partitioned_table FOR VALUES FROM ('2021-01-01') TO ('2021-01-03');
|
||||
CREATE TABLE date_partitioned_table_2021_01_02 PARTITION OF date_partitioned_table FOR VALUES FROM ('2021-01-05') TO ('2021-01-07');
|
||||
SELECT * FROM get_missing_time_partition_ranges('date_partitioned_table', INTERVAL '2 days', '2021-01-15', '2020-12-30');
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
CREATE TABLE date_partitioned_table_2021_01_01 PARTITION OF date_partitioned_table FOR VALUES FROM ('2021-01-01') TO ('2021-01-02');
|
||||
CREATE TABLE date_partitioned_table_2021_01_02 PARTITION OF date_partitioned_table FOR VALUES FROM ('2021-01-02') TO ('2021-01-04');
|
||||
SELECT * FROM get_missing_time_partition_ranges('date_partitioned_table', INTERVAL '2 days', '2021-01-05', '2020-12-30');
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
CREATE TABLE date_partitioned_table_2021_01_01 PARTITION OF date_partitioned_table FOR VALUES FROM ('2021-01-01') TO ('2021-01-03');
|
||||
CREATE TABLE date_partitioned_table_2021_01_02 PARTITION OF date_partitioned_table FOR VALUES FROM ('2021-01-04') TO ('2021-01-06');
|
||||
SELECT * FROM get_missing_time_partition_ranges('date_partitioned_table', INTERVAL '2 days', '2021-01-15', '2020-12-30');
|
||||
ROLLBACK;
|
||||
|
||||
DROP TABLE date_partitioned_table;
|
||||
|
||||
-- 2) test timestamp with time zone partitioend table
|
||||
CREATE TABLE tstz_partitioned_table(
|
||||
measureid integer,
|
||||
eventdatetime timestamp with time zone,
|
||||
measure_data jsonb) PARTITION BY RANGE(eventdatetime);
|
||||
|
||||
SELECT create_distributed_table('tstz_partitioned_table','measureid');
|
||||
|
||||
-- test with various intervals
|
||||
SELECT * FROM get_missing_time_partition_ranges('tstz_partitioned_table', INTERVAL '30 minutes', '2021-01-01 12:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM get_missing_time_partition_ranges('tstz_partitioned_table', INTERVAL '1 hour', '2021-01-02 00:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM get_missing_time_partition_ranges('tstz_partitioned_table', INTERVAL '6 hours', '2021-01-02 00:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM get_missing_time_partition_ranges('tstz_partitioned_table', INTERVAL '12 hours', '2021-01-02 00:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM get_missing_time_partition_ranges('tstz_partitioned_table', INTERVAL '1 day', '2021-01-05 00:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM get_missing_time_partition_ranges('tstz_partitioned_table', INTERVAL '1 week', '2021-01-15 00:00:00', '2021-01-01 00:00:00');
|
||||
|
||||
-- test with from_date > to_date
|
||||
SELECT * FROM get_missing_time_partition_ranges('tstz_partitioned_table', INTERVAL '1 day', '2021-01-01 00:00:00', '2021-01-05 00:00:00');
|
||||
|
||||
-- test with existing partitions
|
||||
BEGIN;
|
||||
CREATE TABLE tstz_partitioned_table_2021_01_01 PARTITION OF tstz_partitioned_table FOR VALUES FROM ('2021-01-01 00:00:00') TO ('2021-01-02 00:00:00');
|
||||
SELECT * FROM get_missing_time_partition_ranges('tstz_partitioned_table', INTERVAL '1 day', '2021-01-05 00:00:00', '2020-12-30 00:00:00');
|
||||
SELECT * FROM get_missing_time_partition_ranges('tstz_partitioned_table', INTERVAL '2 days', '2021-01-05 00:00:00', '2020-12-30 00:00:00');
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
CREATE TABLE tstz_partitioned_table_2021_01_01 PARTITION OF tstz_partitioned_table FOR VALUES FROM ('2021-01-01 00:00:00') TO ('2021-01-02 00:00:00');
|
||||
CREATE TABLE tstz_partitioned_table_2021_01_02 PARTITION OF tstz_partitioned_table FOR VALUES FROM ('2021-01-02 00:00:00') TO ('2021-01-03 00:00:00');
|
||||
SELECT * FROM get_missing_time_partition_ranges('tstz_partitioned_table', INTERVAL '1 day', '2021-01-05 00:00:00', '2020-12-30 00:00:00');
|
||||
SELECT * FROM get_missing_time_partition_ranges('tstz_partitioned_table', INTERVAL '2 days', '2021-01-05 00:00:00', '2020-12-30 00:00:00');
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
CREATE TABLE tstz_partitioned_table_2021_01_01 PARTITION OF tstz_partitioned_table FOR VALUES FROM ('2021-01-01 00:00:00') TO ('2021-01-03 00:00:00');
|
||||
CREATE TABLE tstz_partitioned_table_2021_01_02 PARTITION OF tstz_partitioned_table FOR VALUES FROM ('2021-01-05 00:00:00') TO ('2021-01-07 00:00:00');
|
||||
SELECT * FROM get_missing_time_partition_ranges('tstz_partitioned_table', INTERVAL '2 days', '2021-01-15 00:00:00', '2020-12-30 00:00:00');
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
CREATE TABLE tstz_partitioned_table_2021_01_01 PARTITION OF tstz_partitioned_table FOR VALUES FROM ('2021-01-01 00:00:00') TO ('2021-01-02 00:00:00');
|
||||
CREATE TABLE tstz_partitioned_table_2021_01_02 PARTITION OF tstz_partitioned_table FOR VALUES FROM ('2021-01-02 00:00:00') TO ('2021-01-04 00:00:00');
|
||||
SELECT * FROM get_missing_time_partition_ranges('tstz_partitioned_table', INTERVAL '2 days', '2021-01-05 00:00:00', '2020-12-30 00:00:00');
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
CREATE TABLE tstz_partitioned_table_2021_01_01 PARTITION OF tstz_partitioned_table FOR VALUES FROM ('2021-01-01 00:00:00') TO ('2021-01-03 00:00:00');
|
||||
CREATE TABLE tstz_partitioned_table_2021_01_02 PARTITION OF tstz_partitioned_table FOR VALUES FROM ('2021-01-04 00:00:00') TO ('2021-01-06 00:00:00');
|
||||
SELECT * FROM get_missing_time_partition_ranges('tstz_partitioned_table', INTERVAL '2 days', '2021-01-15 00:00:00', '2020-12-30 00:00:00');
|
||||
ROLLBACK;
|
||||
|
||||
DROP TABLE tstz_partitioned_table;
|
||||
|
||||
-- 3) test timestamp without time zone partitioend table
|
||||
CREATE TABLE tswtz_partitioned_table(
|
||||
measureid integer,
|
||||
eventdatetime timestamp without time zone,
|
||||
measure_data jsonb) PARTITION BY RANGE(eventdatetime);
|
||||
|
||||
SELECT create_distributed_table('tswtz_partitioned_table','measureid');
|
||||
|
||||
-- test with various intervals
|
||||
SELECT * FROM get_missing_time_partition_ranges('tswtz_partitioned_table', INTERVAL '30 minutes', '2021-01-01 12:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM get_missing_time_partition_ranges('tswtz_partitioned_table', INTERVAL '1 hour', '2021-01-02 00:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM get_missing_time_partition_ranges('tswtz_partitioned_table', INTERVAL '6 hours', '2021-01-02 00:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM get_missing_time_partition_ranges('tswtz_partitioned_table', INTERVAL '12 hours', '2021-01-02 00:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM get_missing_time_partition_ranges('tswtz_partitioned_table', INTERVAL '1 day', '2021-01-05 00:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM get_missing_time_partition_ranges('tswtz_partitioned_table', INTERVAL '1 week', '2021-01-15 00:00:00', '2021-01-01 00:00:00');
|
||||
|
||||
-- test with from_date > to_date
|
||||
SELECT * FROM get_missing_time_partition_ranges('tswtz_partitioned_table', INTERVAL '1 day', '2021-01-01 00:00:00', '2021-01-05 00:00:00');
|
||||
|
||||
-- test with existing partitions
|
||||
BEGIN;
|
||||
CREATE TABLE tswtz_partitioned_table_2021_01_01 PARTITION OF tswtz_partitioned_table FOR VALUES FROM ('2021-01-01 00:00:00') TO ('2021-01-02 00:00:00');
|
||||
SELECT * FROM get_missing_time_partition_ranges('tswtz_partitioned_table', INTERVAL '1 day', '2021-01-05 00:00:00', '2020-12-30 00:00:00');
|
||||
SELECT * FROM get_missing_time_partition_ranges('tswtz_partitioned_table', INTERVAL '2 days', '2021-01-05 00:00:00', '2020-12-30 00:00:00');
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
CREATE TABLE tswtz_partitioned_table_2021_01_01 PARTITION OF tswtz_partitioned_table FOR VALUES FROM ('2021-01-01 00:00:00') TO ('2021-01-02 00:00:00');
|
||||
CREATE TABLE tswtz_partitioned_table_2021_01_02 PARTITION OF tswtz_partitioned_table FOR VALUES FROM ('2021-01-02 00:00:00') TO ('2021-01-03 00:00:00');
|
||||
SELECT * FROM get_missing_time_partition_ranges('tswtz_partitioned_table', INTERVAL '1 day', '2021-01-05 00:00:00', '2020-12-30 00:00:00');
|
||||
SELECT * FROM get_missing_time_partition_ranges('tswtz_partitioned_table', INTERVAL '2 days', '2021-01-05 00:00:00', '2020-12-30 00:00:00');
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
CREATE TABLE tswtz_partitioned_table_2021_01_01 PARTITION OF tswtz_partitioned_table FOR VALUES FROM ('2021-01-01 00:00:00') TO ('2021-01-03 00:00:00');
|
||||
CREATE TABLE tswtz_partitioned_table_2021_01_02 PARTITION OF tswtz_partitioned_table FOR VALUES FROM ('2021-01-05 00:00:00') TO ('2021-01-07 00:00:00');
|
||||
SELECT * FROM get_missing_time_partition_ranges('tswtz_partitioned_table', INTERVAL '2 days', '2021-01-15 00:00:00', '2020-12-30 00:00:00');
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
CREATE TABLE tswtz_partitioned_table_2021_01_01 PARTITION OF tswtz_partitioned_table FOR VALUES FROM ('2021-01-01 00:00:00') TO ('2021-01-02 00:00:00');
|
||||
CREATE TABLE tswtz_partitioned_table_2021_01_02 PARTITION OF tswtz_partitioned_table FOR VALUES FROM ('2021-01-02 00:00:00') TO ('2021-01-04 00:00:00');
|
||||
SELECT * FROM get_missing_time_partition_ranges('tswtz_partitioned_table', INTERVAL '2 days', '2021-01-05 00:00:00', '2020-12-30 00:00:00');
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
CREATE TABLE tswtz_partitioned_table_2021_01_01 PARTITION OF tswtz_partitioned_table FOR VALUES FROM ('2021-01-01 00:00:00') TO ('2021-01-03 00:00:00');
|
||||
CREATE TABLE tswtz_partitioned_table_2021_01_02 PARTITION OF tswtz_partitioned_table FOR VALUES FROM ('2021-01-04 00:00:00') TO ('2021-01-06 00:00:00');
|
||||
SELECT * FROM get_missing_time_partition_ranges('tswtz_partitioned_table', INTERVAL '2 days', '2021-01-15 00:00:00', '2020-12-30 00:00:00');
|
||||
ROLLBACK;
|
||||
|
||||
DROP TABLE tswtz_partitioned_table;
|
||||
|
||||
-- 4) test with weird name
|
||||
CREATE TABLE "test !/ \n _dist_123_table"(
|
||||
measureid integer,
|
||||
eventdatetime timestamp without time zone,
|
||||
measure_data jsonb) PARTITION BY RANGE(eventdatetime);
|
||||
|
||||
SELECT create_distributed_table('"test !/ \n _dist_123_table"','measureid');
|
||||
|
||||
-- test with various intervals
|
||||
SELECT * FROM get_missing_time_partition_ranges('"test !/ \n _dist_123_table"', INTERVAL '30 minutes', '2021-01-01 12:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM get_missing_time_partition_ranges('"test !/ \n _dist_123_table"', INTERVAL '1 hour', '2021-01-01 12:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM get_missing_time_partition_ranges('"test !/ \n _dist_123_table"', INTERVAL '6 hours', '2021-01-02 00:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM get_missing_time_partition_ranges('"test !/ \n _dist_123_table"', INTERVAL '1 day', '2021-01-03 00:00:00', '2021-01-01 00:00:00');
|
||||
|
||||
DROP TABLE "test !/ \n _dist_123_table";
|
||||
|
||||
-- b) test create_time_partitions
|
||||
-- 1) test create_time_partitions with date partitioned table
|
||||
CREATE TABLE date_partitioned_table(
|
||||
measureid integer,
|
||||
eventdate date,
|
||||
measure_data jsonb) PARTITION BY RANGE(eventdate);
|
||||
|
||||
-- test interval must be multiple days for date partitioned table
|
||||
SELECT create_time_partitions('date_partitioned_table', INTERVAL '6 hours', '2022-01-01', '2021-01-01');
|
||||
SELECT create_time_partitions('date_partitioned_table', INTERVAL '1 week 1 day 1 hour', '2022-01-01', '2021-01-01');
|
||||
|
||||
-- test with various intervals
|
||||
BEGIN;
|
||||
SELECT create_time_partitions('date_partitioned_table', INTERVAL '1 day', '2021-02-01', '2021-01-01');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'date_partitioned_table'::regclass ORDER BY 3;
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
SELECT create_time_partitions('date_partitioned_table', INTERVAL '1 week', '2022-01-01', '2021-01-01');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'date_partitioned_table'::regclass ORDER BY 3;
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
SELECT create_time_partitions('date_partitioned_table', INTERVAL '1 month', '2022-01-01', '2021-01-01');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'date_partitioned_table'::regclass ORDER BY 3;
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
SELECT create_time_partitions('date_partitioned_table', INTERVAL '3 months', '2022-01-01', '2021-01-01');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'date_partitioned_table'::regclass ORDER BY 3;
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
SELECT create_time_partitions('date_partitioned_table', INTERVAL '6 months', '2022-01-01', '2021-01-01');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'date_partitioned_table'::regclass ORDER BY 3;
|
||||
ROLLBACK;
|
||||
|
||||
-- test with from_date > to_date
|
||||
SELECT * FROM create_time_partitions('date_partitioned_table', INTERVAL '1 day', '2021-01-01', '2021-02-01');
|
||||
|
||||
-- test with existing partitions
|
||||
BEGIN;
|
||||
CREATE TABLE date_partitioned_table_2021_01_01 PARTITION OF date_partitioned_table FOR VALUES FROM ('2021-01-01') TO ('2021-01-02');
|
||||
SELECT create_time_partitions('date_partitioned_table', INTERVAL '1 day', '2021-01-05', '2020-12-30');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'date_partitioned_table'::regclass ORDER BY 3;
|
||||
SELECT create_time_partitions('date_partitioned_table', INTERVAL '2 days', '2021-01-15', '2020-12-25');
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
CREATE TABLE date_partitioned_table_2021_01_01 PARTITION OF date_partitioned_table FOR VALUES FROM ('2021-01-01') TO ('2021-01-02');
|
||||
CREATE TABLE date_partitioned_table_2021_01_02 PARTITION OF date_partitioned_table FOR VALUES FROM ('2021-01-02') TO ('2021-01-03');
|
||||
SELECT create_time_partitions('date_partitioned_table', INTERVAL '1 day', '2021-01-05', '2020-12-30');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'date_partitioned_table'::regclass ORDER BY 3;
|
||||
SELECT create_time_partitions('date_partitioned_table', INTERVAL '2 days', '2021-01-05', '2020-12-30');
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
CREATE TABLE date_partitioned_table_2021_01_01 PARTITION OF date_partitioned_table FOR VALUES FROM ('2021-01-01') TO ('2021-01-03');
|
||||
CREATE TABLE date_partitioned_table_2021_01_02 PARTITION OF date_partitioned_table FOR VALUES FROM ('2021-01-05') TO ('2021-01-07');
|
||||
SELECT create_time_partitions('date_partitioned_table', INTERVAL '2 days', '2021-01-15', '2020-12-30');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'date_partitioned_table'::regclass ORDER BY 3;
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
CREATE TABLE date_partitioned_table_2021_01_01 PARTITION OF date_partitioned_table FOR VALUES FROM ('2021-01-01') TO ('2021-01-02');
|
||||
CREATE TABLE date_partitioned_table_2020_01_02 PARTITION OF date_partitioned_table FOR VALUES FROM ('2021-01-02') TO ('2021-01-04');
|
||||
SELECT create_time_partitions('date_partitioned_table', INTERVAL '1 day', '2021-01-05', '2020-12-30');
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
CREATE TABLE date_partitioned_table_2021_01_01 PARTITION OF date_partitioned_table FOR VALUES FROM ('2021-01-01') TO ('2021-01-03');
|
||||
CREATE TABLE date_partitioned_table_2021_01_02 PARTITION OF date_partitioned_table FOR VALUES FROM ('2021-01-04') TO ('2021-01-06');
|
||||
SELECT create_time_partitions('date_partitioned_table', INTERVAL '2 days', '2021-01-15', '2020-12-30');
|
||||
ROLLBACK;
|
||||
|
||||
DROP TABLE date_partitioned_table;
|
||||
|
||||
-- 2) test timestamp with time zone partitioend table
|
||||
CREATE TABLE tstz_partitioned_table(
|
||||
measureid integer,
|
||||
eventdatetime timestamp with time zone,
|
||||
measure_data jsonb) PARTITION BY RANGE(eventdatetime);
|
||||
|
||||
-- test with various intervals
|
||||
BEGIN;
|
||||
SELECT create_time_partitions('tstz_partitioned_table', INTERVAL '30 minutes', '2021-01-01 12:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'tstz_partitioned_table'::regclass ORDER BY 3;
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
SELECT create_time_partitions('tstz_partitioned_table', INTERVAL '1 hour', '2021-01-02 00:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'tstz_partitioned_table'::regclass ORDER BY 3;
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
SELECT create_time_partitions('tstz_partitioned_table', INTERVAL '6 hours', '2021-01-02 00:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'tstz_partitioned_table'::regclass ORDER BY 3;
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
SELECT create_time_partitions('tstz_partitioned_table', INTERVAL '12 hours', '2021-01-02 00:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'tstz_partitioned_table'::regclass ORDER BY 3;
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
SELECT create_time_partitions('tstz_partitioned_table', INTERVAL '1 day', '2021-01-05 00:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'tstz_partitioned_table'::regclass ORDER BY 3;
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
SELECT create_time_partitions('tstz_partitioned_table', INTERVAL '1 week', '2021-01-15 00:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'tstz_partitioned_table'::regclass ORDER BY 3;
|
||||
ROLLBACK;
|
||||
|
||||
-- test with from_date > to_date
|
||||
SELECT create_time_partitions('tstz_partitioned_table', INTERVAL '1 day', '2021-01-01 00:00:00', '2021-01-05 00:00:00');
|
||||
|
||||
-- test with existing partitions
|
||||
BEGIN;
|
||||
CREATE TABLE tstz_partitioned_table_2021_01_01 PARTITION OF tstz_partitioned_table FOR VALUES FROM ('2021-01-01 00:00:00') TO ('2021-01-02 00:00:00');
|
||||
SELECT create_time_partitions('tstz_partitioned_table', INTERVAL '1 day', '2021-01-05 00:00:00', '2020-12-30 00:00:00');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'tstz_partitioned_table'::regclass ORDER BY 3;
|
||||
SELECT * FROM get_missing_time_partition_ranges('tstz_partitioned_table', INTERVAL '2 days', '2021-01-05 00:00:00', '2020-12-30 00:00:00');
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
CREATE TABLE tstz_partitioned_table_2021_01_01 PARTITION OF tstz_partitioned_table FOR VALUES FROM ('2021-01-01 00:00:00') TO ('2021-01-02 00:00:00');
|
||||
CREATE TABLE tstz_partitioned_table_2021_01_02 PARTITION OF tstz_partitioned_table FOR VALUES FROM ('2021-01-02 00:00:00') TO ('2021-01-03 00:00:00');
|
||||
SELECT create_time_partitions('tstz_partitioned_table', INTERVAL '1 day', '2021-01-05 00:00:00', '2020-12-30 00:00:00');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'tstz_partitioned_table'::regclass ORDER BY 3;
|
||||
SELECT create_time_partitions('tstz_partitioned_table', INTERVAL '2 days', '2021-01-05 00:00:00', '2020-12-30 00:00:00');
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
CREATE TABLE tstz_partitioned_table_2021_01_01 PARTITION OF tstz_partitioned_table FOR VALUES FROM ('2021-01-01 00:00:00') TO ('2021-01-03 00:00:00');
|
||||
CREATE TABLE tstz_partitioned_table_2021_01_02 PARTITION OF tstz_partitioned_table FOR VALUES FROM ('2021-01-05 00:00:00') TO ('2021-01-07 00:00:00');
|
||||
SELECT create_time_partitions('tstz_partitioned_table', INTERVAL '2 days', '2021-01-15 00:00:00', '2020-12-30 00:00:00');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'tstz_partitioned_table'::regclass ORDER BY 3;
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
CREATE TABLE tstz_partitioned_table_2021_01_01 PARTITION OF tstz_partitioned_table FOR VALUES FROM ('2021-01-01 00:00:00') TO ('2021-01-02 00:00:00');
|
||||
CREATE TABLE tstz_partitioned_table_2021_01_02 PARTITION OF tstz_partitioned_table FOR VALUES FROM ('2021-01-02 00:00:00') TO ('2021-01-04 00:00:00');
|
||||
SELECT create_time_partitions('tstz_partitioned_table', INTERVAL '2 days', '2021-01-05 00:00:00', '2020-12-30 00:00:00');
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
CREATE TABLE tstz_partitioned_table_2021_01_01 PARTITION OF tstz_partitioned_table FOR VALUES FROM ('2021-01-01 00:00:00') TO ('2021-01-03 00:00:00');
|
||||
CREATE TABLE tstz_partitioned_table_2021_01_02 PARTITION OF tstz_partitioned_table FOR VALUES FROM ('2021-01-04 00:00:00') TO ('2021-01-06 00:00:00');
|
||||
SELECT create_time_partitions('tstz_partitioned_table', INTERVAL '2 days', '2021-01-15 00:00:00', '2020-12-30 00:00:00');
|
||||
ROLLBACK;
|
||||
|
||||
DROP TABLE tstz_partitioned_table;
|
||||
|
||||
-- 3) test timestamp without time zone partitioend table
|
||||
CREATE TABLE tswtz_partitioned_table(
|
||||
measureid integer,
|
||||
eventdatetime timestamp without time zone,
|
||||
measure_data jsonb) PARTITION BY RANGE(eventdatetime);
|
||||
|
||||
SELECT create_distributed_table('tswtz_partitioned_table','measureid');
|
||||
|
||||
BEGIN;
|
||||
SELECT create_time_partitions('tswtz_partitioned_table', INTERVAL '30 minutes', '2021-01-01 12:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'tswtz_partitioned_table'::regclass ORDER BY 3;
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
SELECT create_time_partitions('tswtz_partitioned_table', INTERVAL '1 hour', '2021-01-02 00:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'tswtz_partitioned_table'::regclass ORDER BY 3;
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
SELECT create_time_partitions('tswtz_partitioned_table', INTERVAL '6 hours', '2021-01-02 00:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'tswtz_partitioned_table'::regclass ORDER BY 3;
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
SELECT create_time_partitions('tswtz_partitioned_table', INTERVAL '12 hours', '2021-01-02 00:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'tswtz_partitioned_table'::regclass ORDER BY 3;
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
SELECT create_time_partitions('tswtz_partitioned_table', INTERVAL '1 day', '2021-01-05 00:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'tswtz_partitioned_table'::regclass ORDER BY 3;
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
SELECT create_time_partitions('tswtz_partitioned_table', INTERVAL '1 week', '2021-01-15 00:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'tswtz_partitioned_table'::regclass ORDER BY 3;
|
||||
ROLLBACK;
|
||||
|
||||
-- test with from_date > to_date
|
||||
SELECT create_time_partitions('tswtz_partitioned_table', INTERVAL '1 day', '2021-01-01 00:00:00', '2021-01-05 00:00:00');
|
||||
|
||||
-- test with existing partitions
|
||||
BEGIN;
|
||||
CREATE TABLE tswtz_partitioned_table_2021_01_01 PARTITION OF tswtz_partitioned_table FOR VALUES FROM ('2021-01-01 00:00:00') TO ('2021-01-02 00:00:00');
|
||||
SELECT create_time_partitions('tswtz_partitioned_table', INTERVAL '1 day', '2021-01-05 00:00:00', '2020-12-30 00:00:00');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'tswtz_partitioned_table'::regclass ORDER BY 3;
|
||||
SELECT create_time_partitions('tswtz_partitioned_table', INTERVAL '2 days', '2021-01-05 00:00:00', '2020-12-30 00:00:00');
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
CREATE TABLE tswtz_partitioned_table_2021_01_01 PARTITION OF tswtz_partitioned_table FOR VALUES FROM ('2021-01-01 00:00:00') TO ('2021-01-02 00:00:00');
|
||||
CREATE TABLE tswtz_partitioned_table_2021_01_02 PARTITION OF tswtz_partitioned_table FOR VALUES FROM ('2021-01-02 00:00:00') TO ('2021-01-03 00:00:00');
|
||||
SELECT create_time_partitions('tswtz_partitioned_table', INTERVAL '1 day', '2021-01-05 00:00:00', '2020-12-30 00:00:00');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'tswtz_partitioned_table'::regclass ORDER BY 3;
|
||||
SELECT create_time_partitions('tswtz_partitioned_table', INTERVAL '2 days', '2021-01-05 00:00:00', '2020-12-30 00:00:00');
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
CREATE TABLE tswtz_partitioned_table_2020_01_01 PARTITION OF tswtz_partitioned_table FOR VALUES FROM ('2021-01-01 00:00:00') TO ('2021-01-03 00:00:00');
|
||||
CREATE TABLE tswtz_partitioned_table_2020_01_02 PARTITION OF tswtz_partitioned_table FOR VALUES FROM ('2021-01-05 00:00:00') TO ('2021-01-07 00:00:00');
|
||||
SELECT create_time_partitions('tswtz_partitioned_table', INTERVAL '2 days', '2021-01-15 00:00:00', '2020-12-30 00:00:00');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'tswtz_partitioned_table'::regclass ORDER BY 3;
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
CREATE TABLE tswtz_partitioned_table_2020_01_01 PARTITION OF tswtz_partitioned_table FOR VALUES FROM ('2021-01-01 00:00:00') TO ('2021-01-02 00:00:00');
|
||||
CREATE TABLE tswtz_partitioned_table_2020_01_02 PARTITION OF tswtz_partitioned_table FOR VALUES FROM ('2021-01-02 00:00:00') TO ('2021-01-04 00:00:00');
|
||||
SELECT create_time_partitions('tswtz_partitioned_table', INTERVAL '2 days', '2021-01-05 00:00:00', '2020-12-30 00:00:00');
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
CREATE TABLE tswtz_partitioned_table_2020_01_01 PARTITION OF tswtz_partitioned_table FOR VALUES FROM ('2021-01-01 00:00:00') TO ('2021-01-03 00:00:00');
|
||||
CREATE TABLE tswtz_partitioned_table_2020_01_02 PARTITION OF tswtz_partitioned_table FOR VALUES FROM ('2021-01-04 00:00:00') TO ('2021-01-06 00:00:00');
|
||||
SELECT create_time_partitions('tswtz_partitioned_table', INTERVAL '2 days', '2021-01-15 00:00:00', '2020-12-30 00:00:00');
|
||||
ROLLBACK;
|
||||
|
||||
DROP TABLE tswtz_partitioned_table;
|
||||
|
||||
-- 4) test with weird name
|
||||
CREATE TABLE "test !/ \n _dist_123_table"(
|
||||
measureid integer,
|
||||
eventdatetime timestamp without time zone,
|
||||
measure_data jsonb) PARTITION BY RANGE(eventdatetime);
|
||||
|
||||
SELECT create_distributed_table('"test !/ \n _dist_123_table"','measureid');
|
||||
|
||||
-- test with various intervals
|
||||
BEGIN;
|
||||
SELECT create_time_partitions('"test !/ \n _dist_123_table"', INTERVAL '30 minutes', '2021-01-01 12:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM time_partitions WHERE parent_table = '"test !/ \n _dist_123_table"'::regclass ORDER BY 3;
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
SELECT create_time_partitions('"test !/ \n _dist_123_table"', INTERVAL '6 hours', '2021-01-02 00:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM time_partitions WHERE parent_table = '"test !/ \n _dist_123_table"'::regclass ORDER BY 3;
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
SELECT create_time_partitions('"test !/ \n _dist_123_table"', INTERVAL '1 day', '2021-01-03 00:00:00', '2021-01-01 00:00:00');
|
||||
SELECT * FROM time_partitions WHERE parent_table = '"test !/ \n _dist_123_table"'::regclass ORDER BY 3;
|
||||
ROLLBACK;
|
||||
|
||||
DROP TABLE "test !/ \n _dist_123_table";
|
||||
|
||||
-- 5) test with distributed table
|
||||
CREATE TABLE date_distributed_partitioned_table(
|
||||
measureid integer,
|
||||
eventdate date,
|
||||
measure_data jsonb) PARTITION BY RANGE(eventdate);
|
||||
|
||||
SELECT create_distributed_table('date_distributed_partitioned_table', 'measureid');
|
||||
|
||||
-- test interval must be multiple days for date partitioned table
|
||||
SELECT create_time_partitions('date_distributed_partitioned_table', INTERVAL '6 hours', '2022-01-01', '2021-01-01');
|
||||
SELECT create_time_partitions('date_distributed_partitioned_table', INTERVAL '1 week 1 day 1 hour', '2022-01-01', '2021-01-01');
|
||||
|
||||
-- test with various intervals
|
||||
BEGIN;
|
||||
SELECT create_time_partitions('date_distributed_partitioned_table', INTERVAL '1 day', '2021-02-01', '2021-01-01');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'date_distributed_partitioned_table'::regclass ORDER BY 3;
|
||||
ROLLBACK;
|
||||
|
||||
BEGIN;
|
||||
SELECT create_time_partitions('date_distributed_partitioned_table', INTERVAL '1 week', '2022-01-01', '2021-01-01');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'date_distributed_partitioned_table'::regclass ORDER BY 3;
|
||||
ROLLBACK;
|
||||
|
||||
DROP TABLE date_distributed_partitioned_table;
|
||||
|
||||
-- pi test with parameter names
|
||||
CREATE TABLE pi_table(
|
||||
event_id bigserial,
|
||||
event_time timestamptz default now(),
|
||||
payload text) PARTITION BY RANGE (event_time);
|
||||
|
||||
BEGIN;
|
||||
SELECT create_time_partitions('pi_table', start_from := '2021-08-01', end_at := '2021-10-01', partition_interval := pi() * interval '1 day');
|
||||
SELECT * FROM time_partitions WHERE parent_table = 'pi_table'::regclass ORDER BY 3;
|
||||
ROLLBACK;
|
||||
|
||||
DROP TABLE pi_table;
|
||||
|
||||
-- c) test drop_old_time_partitions
|
||||
-- 1) test with date partitioned table
|
||||
CREATE TABLE date_partitioned_table_to_exp (event_date date, event int) partition by range (event_date);
|
||||
SELECT create_distributed_table('date_partitioned_table_to_exp', 'event');
|
||||
|
||||
CREATE TABLE date_partitioned_table_to_exp_d00 PARTITION OF date_partitioned_table_to_exp FOR VALUES FROM ('2000-01-01') TO ('2009-12-31');
|
||||
CREATE TABLE date_partitioned_table_to_exp_d10 PARTITION OF date_partitioned_table_to_exp FOR VALUES FROM ('2010-01-01') TO ('2019-12-31');
|
||||
CREATE TABLE date_partitioned_table_to_exp_d20 PARTITION OF date_partitioned_table_to_exp FOR VALUES FROM ('2020-01-01') TO ('2029-12-31');
|
||||
INSERT INTO date_partitioned_table_to_exp VALUES ('2005-01-01', 1);
|
||||
INSERT INTO date_partitioned_table_to_exp VALUES ('2015-01-01', 2);
|
||||
INSERT INTO date_partitioned_table_to_exp VALUES ('2025-01-01', 3);
|
||||
|
||||
\set VERBOSITY terse
|
||||
|
||||
-- expire no partitions
|
||||
CALL drop_old_time_partitions('date_partitioned_table_to_exp', '1999-01-01');
|
||||
SELECT partition FROM time_partitions WHERE parent_table = 'date_partitioned_table_to_exp'::regclass ORDER BY partition::text;
|
||||
|
||||
-- expire 2 old partitions
|
||||
CALL drop_old_time_partitions('date_partitioned_table_to_exp', '2021-01-01');
|
||||
SELECT partition FROM time_partitions WHERE parent_table = 'date_partitioned_table_to_exp'::regclass ORDER BY partition::text;
|
||||
|
||||
\set VERBOSITY default
|
||||
DROP TABLE date_partitioned_table_to_exp;
|
||||
|
||||
-- 2) test with timestamptz partitioned table
|
||||
CREATE TABLE tstz_partitioned_table_to_exp (event_time timestamptz, event int) partition by range (event_time);
|
||||
SELECT create_distributed_table('tstz_partitioned_table_to_exp', 'event');
|
||||
|
||||
CREATE TABLE tstz_partitioned_table_to_exp_d0 PARTITION OF tstz_partitioned_table_to_exp FOR VALUES FROM ('2021-01-01 02:00:00+00') TO ('2021-01-01 06:00:00+00');
|
||||
CREATE TABLE tstz_partitioned_table_to_exp_d1 PARTITION OF tstz_partitioned_table_to_exp FOR VALUES FROM ('2021-01-01 06:00:00+00') TO ('2021-01-01 10:00:00+00');
|
||||
CREATE TABLE tstz_partitioned_table_to_exp_d2 PARTITION OF tstz_partitioned_table_to_exp FOR VALUES FROM ('2021-01-01 10:00:00+00') TO ('2021-01-01 14:00:00+00');
|
||||
INSERT INTO tstz_partitioned_table_to_exp VALUES ('2021-01-01 03:00:00+00', 1);
|
||||
INSERT INTO tstz_partitioned_table_to_exp VALUES ('2021-01-01 09:00:00+00', 2);
|
||||
INSERT INTO tstz_partitioned_table_to_exp VALUES ('2021-01-01 13:00:00+00', 3);
|
||||
|
||||
\set VERBOSITY terse
|
||||
|
||||
-- expire no partitions
|
||||
CALL drop_old_time_partitions('tstz_partitioned_table_to_exp', '2021-01-01 01:00:00+00');
|
||||
SELECT partition FROM time_partitions WHERE parent_table = 'tstz_partitioned_table_to_exp'::regclass ORDER BY partition::text;
|
||||
|
||||
-- expire 2 old partitions
|
||||
CALL drop_old_time_partitions('tstz_partitioned_table_to_exp', '2021-01-01 12:00:00+00');
|
||||
SELECT partition FROM time_partitions WHERE parent_table = 'tstz_partitioned_table_to_exp'::regclass ORDER BY partition::text;
|
||||
|
||||
\set VERBOSITY default
|
||||
DROP TABLE tstz_partitioned_table_to_exp;
|
||||
|
||||
-- 3) test with weird table name
|
||||
CREATE TABLE "test !/ \n _dist_123_table_exp" (event_time timestamptz, event int) partition by range (event_time);
|
||||
SELECT create_distributed_table('"test !/ \n _dist_123_table_exp"', 'event');
|
||||
|
||||
CREATE TABLE tstz_partitioned_table_to_exp_d0 PARTITION OF "test !/ \n _dist_123_table_exp" FOR VALUES FROM ('2021-01-01 02:00:00+00') TO ('2021-01-01 06:00:00+00');
|
||||
CREATE TABLE tstz_partitioned_table_to_exp_d1 PARTITION OF "test !/ \n _dist_123_table_exp" FOR VALUES FROM ('2021-01-01 06:00:00+00') TO ('2021-01-01 10:00:00+00');
|
||||
CREATE TABLE tstz_partitioned_table_to_exp_d2 PARTITION OF "test !/ \n _dist_123_table_exp" FOR VALUES FROM ('2021-01-01 10:00:00+00') TO ('2021-01-01 14:00:00+00');
|
||||
INSERT INTO "test !/ \n _dist_123_table_exp" VALUES ('2021-01-01 03:00:00+00', 1);
|
||||
INSERT INTO "test !/ \n _dist_123_table_exp" VALUES ('2021-01-01 09:00:00+00', 2);
|
||||
INSERT INTO "test !/ \n _dist_123_table_exp" VALUES ('2021-01-01 13:00:00+00', 3);
|
||||
|
||||
\set VERBOSITY terse
|
||||
|
||||
-- expire no partitions
|
||||
CALL drop_old_time_partitions('"test !/ \n _dist_123_table_exp"', '2021-01-01 01:00:00+00');
|
||||
SELECT partition FROM time_partitions WHERE parent_table = '"test !/ \n _dist_123_table_exp"'::regclass ORDER BY partition::text;
|
||||
|
||||
-- expire 2 old partitions
|
||||
CALL drop_old_time_partitions('"test !/ \n _dist_123_table_exp"', '2021-01-01 12:00:00+00');
|
||||
SELECT partition FROM time_partitions WHERE parent_table = '"test !/ \n _dist_123_table_exp"'::regclass ORDER BY partition::text;
|
||||
|
||||
\set VERBOSITY default
|
||||
DROP TABLE "test !/ \n _dist_123_table_exp";
|
||||
|
||||
-- d) invalid tables for helper UDFs
|
||||
CREATE TABLE multiple_partition_column_table(
|
||||
event_id bigserial,
|
||||
event_time timestamptz,
|
||||
payload text) PARTITION BY RANGE (event_time, event_id);
|
||||
|
||||
SELECT create_time_partitions('multiple_partition_column_table', INTERVAL '1 month', now() + INTERVAL '1 year');
|
||||
CALL drop_old_time_partitions('multiple_partition_column_table', now());
|
||||
DROP TABLE multiple_partition_column_table;
|
||||
|
||||
CREATE TABLE invalid_partition_column_table(
|
||||
event_id bigserial,
|
||||
event_time bigint,
|
||||
payload text) PARTITION BY RANGE (event_time);
|
||||
|
||||
SELECT create_time_partitions('invalid_partition_column_table', INTERVAL '1 month', now() + INTERVAL '1 year');
|
||||
CALL drop_old_time_partitions('invalid_partition_column_table', now());
|
||||
DROP TABLE invalid_partition_column_table;
|
||||
|
||||
CREATE TABLE non_partitioned_table(
|
||||
event_id bigserial,
|
||||
event_time timestamptz,
|
||||
payload text);
|
||||
|
||||
SELECT create_time_partitions('non_partitioned_table', INTERVAL '1 month', now() + INTERVAL '1 year');
|
||||
CALL drop_old_time_partitions('non_partitioned_table', now());
|
||||
DROP TABLE non_partitioned_table;
|
||||
|
||||
DROP SCHEMA partitioning_schema CASCADE;
|
||||
RESET search_path;
|
||||
DROP TABLE IF EXISTS
|
||||
|
|
Loading…
Reference in New Issue