mirror of
https://github.com/timescale/timescaledb.git
synced 2025-05-16 10:33:27 +08:00
Hash partitioning previously relied on coercing (casting) values to strings before calculating a hash value, including creating CHECK constraints with casts. This approach is fairly suboptimal from a performance perspective and might have issues related to different character encodings depending on system. Hash partitioning now instead uses a partitioning function that takes an anyelement type that calls type-dependent hash functions internal to PostgreSQL. This should provide more efficient hashing both by avoiding unnecessary string conversions and by using more optimal type-specific hash functions. Support for the previous hash partitioning function is preserved for backwards compatibility. Hypertables created with the previous function will continue to use to old hashing strategy, while new tables will default to the updated hash partitioning. For safety, this change also blocks changing types on hash-partitioned columns, since it seems hard to guarantee the same hash result between different types.
203 lines
6.5 KiB
PL/PgSQL
203 lines
6.5 KiB
PL/PgSQL
-- This file contains functions associated with creating new
|
|
-- hypertables.
|
|
|
|
-- Creates a new schema if it does not exist.
|
|
CREATE OR REPLACE FUNCTION _timescaledb_internal.create_schema(
|
|
schema_name NAME
|
|
)
|
|
RETURNS VOID LANGUAGE PLPGSQL VOLATILE AS
|
|
$BODY$
|
|
BEGIN
|
|
EXECUTE format(
|
|
$$
|
|
CREATE SCHEMA IF NOT EXISTS %I
|
|
$$, schema_name);
|
|
END
|
|
$BODY$
|
|
SET client_min_messages = WARNING -- suppress NOTICE on IF EXISTS
|
|
;
|
|
|
|
CREATE OR REPLACE FUNCTION _timescaledb_internal.chunk_create_table(
|
|
chunk_id INT,
|
|
tablespace_name NAME
|
|
)
|
|
RETURNS VOID LANGUAGE PLPGSQL VOLATILE AS
|
|
$BODY$
|
|
DECLARE
|
|
chunk_row _timescaledb_catalog.chunk;
|
|
hypertable_row _timescaledb_catalog.hypertable;
|
|
tablespace_clause TEXT := '';
|
|
table_owner NAME;
|
|
tablespace_oid OID;
|
|
BEGIN
|
|
SELECT * INTO STRICT chunk_row
|
|
FROM _timescaledb_catalog.chunk
|
|
WHERE id = chunk_id;
|
|
|
|
SELECT * INTO STRICT hypertable_row
|
|
FROM _timescaledb_catalog.hypertable
|
|
WHERE id = chunk_row.hypertable_id;
|
|
|
|
SELECT t.oid
|
|
INTO tablespace_oid
|
|
FROM pg_catalog.pg_tablespace t
|
|
WHERE t.spcname = tablespace_name;
|
|
|
|
SELECT tableowner
|
|
INTO STRICT table_owner
|
|
FROM pg_catalog.pg_tables
|
|
WHERE schemaname = hypertable_row.schema_name
|
|
AND tablename = hypertable_row.table_name;
|
|
|
|
IF tablespace_oid IS NOT NULL THEN
|
|
tablespace_clause := format('TABLESPACE %s', tablespace_name);
|
|
ELSIF tablespace_name IS NOT NULL THEN
|
|
RAISE EXCEPTION 'No tablespace % in database %', tablespace_name, current_database()
|
|
USING ERRCODE = 'IO501';
|
|
END IF;
|
|
|
|
EXECUTE format(
|
|
$$
|
|
CREATE TABLE IF NOT EXISTS %1$I.%2$I () INHERITS(%3$I.%4$I) %5$s;
|
|
$$,
|
|
chunk_row.schema_name, chunk_row.table_name,
|
|
hypertable_row.schema_name, hypertable_row.table_name, tablespace_clause
|
|
);
|
|
|
|
EXECUTE format(
|
|
$$
|
|
ALTER TABLE %1$I.%2$I OWNER TO %3$I
|
|
$$,
|
|
chunk_row.schema_name, chunk_row.table_name,
|
|
table_owner
|
|
);
|
|
END
|
|
$BODY$;
|
|
|
|
CREATE OR REPLACE FUNCTION _timescaledb_internal.dimension_slice_get_constraint_sql(
|
|
dimension_slice_id INTEGER
|
|
)
|
|
RETURNS TEXT LANGUAGE PLPGSQL VOLATILE AS
|
|
$BODY$
|
|
DECLARE
|
|
dimension_slice_row _timescaledb_catalog.dimension_slice;
|
|
dimension_row _timescaledb_catalog.dimension;
|
|
proargtype OID;
|
|
typecast TEXT = '';
|
|
BEGIN
|
|
SELECT * INTO STRICT dimension_slice_row
|
|
FROM _timescaledb_catalog.dimension_slice
|
|
WHERE id = dimension_slice_id;
|
|
|
|
SELECT * INTO STRICT dimension_row
|
|
FROM _timescaledb_catalog.dimension
|
|
WHERE id = dimension_slice_row.dimension_id;
|
|
|
|
IF dimension_row.partitioning_func IS NOT NULL THEN
|
|
SELECT proargtypes[0] INTO STRICT proargtype
|
|
FROM pg_proc p, pg_namespace n
|
|
WHERE n.nspname = dimension_row.partitioning_func_schema
|
|
AND p.proname = dimension_row.partitioning_func
|
|
AND n.oid = p.pronamespace;
|
|
|
|
-- Check if we are using a legacy partitioning function
|
|
-- that only takes text input
|
|
IF proargtype = 'text'::regtype THEN
|
|
typecast := '::text';
|
|
END IF;
|
|
|
|
return format(
|
|
$$
|
|
%1$I.%2$s(%3$I%4$s) >= %5$L AND %1$I.%2$s(%3$I%4$s) < %6$L
|
|
$$,
|
|
dimension_row.partitioning_func_schema,
|
|
dimension_row.partitioning_func,
|
|
dimension_row.column_name,
|
|
typecast,
|
|
dimension_slice_row.range_start,
|
|
dimension_slice_row.range_end);
|
|
ELSE
|
|
--TODO: only works with time for now
|
|
IF _timescaledb_internal.time_literal_sql(dimension_slice_row.range_start, dimension_row.column_type) =
|
|
_timescaledb_internal.time_literal_sql(dimension_slice_row.range_end, dimension_row.column_type) THEN
|
|
RAISE 'Time based constraints have the same start and end values for column "%": %',
|
|
dimension_row.column_name,
|
|
_timescaledb_internal.time_literal_sql(dimension_slice_row.range_end, dimension_row.column_type);
|
|
END IF;
|
|
return format(
|
|
$$
|
|
%1$I >= %2$s AND %1$I < %3$s
|
|
$$,
|
|
dimension_row.column_name,
|
|
_timescaledb_internal.time_literal_sql(dimension_slice_row.range_start, dimension_row.column_type),
|
|
_timescaledb_internal.time_literal_sql(dimension_slice_row.range_end, dimension_row.column_type));
|
|
END IF;
|
|
END
|
|
$BODY$;
|
|
|
|
-- Outputs the create_hypertable command to recreate the given hypertable.
|
|
--
|
|
-- This is currently used internally for our single hypertable backup tool
|
|
-- so that it knows how to restore the hypertable without user intervention.
|
|
--
|
|
-- It only works for hypertables with up to 2 dimensions.
|
|
CREATE OR REPLACE FUNCTION _timescaledb_internal.get_create_command(
|
|
table_name NAME
|
|
)
|
|
RETURNS TEXT LANGUAGE PLPGSQL VOLATILE AS
|
|
$BODY$
|
|
DECLARE
|
|
h_id INTEGER;
|
|
schema_name NAME;
|
|
time_column NAME;
|
|
time_interval BIGINT;
|
|
space_column NAME;
|
|
space_partitions INTEGER;
|
|
dimension_cnt INTEGER;
|
|
dimension_row record;
|
|
ret TEXT;
|
|
BEGIN
|
|
SELECT h.id, h.schema_name
|
|
FROM _timescaledb_catalog.hypertable AS h
|
|
WHERE h.table_name = get_create_command.table_name
|
|
INTO h_id, schema_name;
|
|
|
|
IF h_id IS NULL THEN
|
|
RAISE EXCEPTION 'hypertable % not found', table_name
|
|
USING ERRCODE = 'IO101';
|
|
END IF;
|
|
|
|
SELECT COUNT(*)
|
|
FROM _timescaledb_catalog.dimension d
|
|
WHERE d.hypertable_id = h_id
|
|
INTO STRICT dimension_cnt;
|
|
|
|
IF dimension_cnt > 2 THEN
|
|
RAISE EXCEPTION 'get_create_command only supports hypertables with up to 2 dimensions'
|
|
USING ERRCODE = 'IO101';
|
|
END IF;
|
|
|
|
FOR dimension_row IN
|
|
SELECT *
|
|
FROM _timescaledb_catalog.dimension d
|
|
WHERE d.hypertable_id = h_id
|
|
LOOP
|
|
IF dimension_row.interval_length IS NOT NULL THEN
|
|
time_column := dimension_row.column_name;
|
|
time_interval := dimension_row.interval_length;
|
|
ELSIF dimension_row.num_slices IS NOT NULL THEN
|
|
space_column := dimension_row.column_name;
|
|
space_partitions := dimension_row.num_slices;
|
|
END IF;
|
|
END LOOP;
|
|
|
|
ret := format($$SELECT create_hypertable('%I.%I', '%I'$$, schema_name, table_name, time_column);
|
|
IF space_column IS NOT NULL THEN
|
|
ret := ret || format($$, '%I', %s$$, space_column, space_partitions);
|
|
END IF;
|
|
ret := ret || format($$, chunk_time_interval => %s, create_default_indexes=>FALSE);$$, time_interval);
|
|
|
|
RETURN ret;
|
|
END
|
|
$BODY$;
|