Skip to content

Commit

Permalink
Provide API for adding hypertable dimensions
Browse files Browse the repository at this point in the history
A new public-facing API `add_dimension(table, column, ...)`
makes it possible to add additional dimensions (partitioning
columns) to a hypertable.

Currently, new dimension can only be added to empty tables.

The code has also been refactored with a corresponding
internal function that is called by both `add_dimension()`
and `create_hypertable()`.
  • Loading branch information
erimatnor committed Jun 27, 2017
1 parent 97681c2 commit 696cc4c
Show file tree
Hide file tree
Showing 10 changed files with 274 additions and 75 deletions.
70 changes: 36 additions & 34 deletions sql/ddl_api.sql
Original file line number Diff line number Diff line change
Expand Up @@ -32,9 +32,6 @@ DECLARE
table_owner NAME;
tablespace_oid OID;
tablespace_name NAME;
time_column_type REGTYPE;
partitioning_column_type REGTYPE;
att_row pg_attribute;
main_table_has_items BOOLEAN;
is_hypertable BOOLEAN;
BEGIN
Expand Down Expand Up @@ -62,35 +59,6 @@ BEGIN
FROM pg_tablespace t
WHERE t.OID = tablespace_oid;

BEGIN
SELECT atttypid
INTO STRICT time_column_type
FROM pg_attribute
WHERE attrelid = main_table AND attname = time_column_name;
EXCEPTION
WHEN NO_DATA_FOUND THEN
RAISE EXCEPTION 'column "%" does not exist', time_column_name
USING ERRCODE = 'IO102';
END;

IF time_column_type NOT IN ('BIGINT', 'INTEGER', 'SMALLINT', 'TIMESTAMP', 'TIMESTAMPTZ') THEN
RAISE EXCEPTION 'illegal type for time column "%": %', time_column_name, time_column_type
USING ERRCODE = 'IO102';
END IF;

IF partitioning_column IS NOT NULL THEN
BEGIN
SELECT atttypid
INTO STRICT partitioning_column_type
FROM pg_attribute
WHERE attrelid = main_table AND attname = partitioning_column;
EXCEPTION
WHEN NO_DATA_FOUND THEN
RAISE EXCEPTION 'column "%" does not exist', partitioning_column
USING ERRCODE = 'IO102';
END;
END IF;

EXECUTE format('SELECT TRUE FROM _timescaledb_catalog.hypertable WHERE
hypertable.schema_name = %L AND
hypertable.table_name = %L',
Expand All @@ -117,12 +85,11 @@ BEGIN
SELECT *
INTO hypertable_row
FROM _timescaledb_internal.create_hypertable_row(
main_table,
schema_name,
table_name,
time_column_name,
time_column_type,
partitioning_column,
partitioning_column_type,
number_partitions,
associated_schema_name,
associated_table_prefix,
Expand Down Expand Up @@ -159,6 +126,41 @@ BEGIN
END
$BODY$;

CREATE OR REPLACE FUNCTION add_dimension(
main_table REGCLASS,
column_name NAME,
number_partitions INTEGER = NULL,
interval_length BIGINT = NULL
)
RETURNS VOID LANGUAGE PLPGSQL VOLATILE AS
$BODY$
<<main_block>>
DECLARE
table_name NAME;
schema_name NAME;
hypertable_row _timescaledb_catalog.hypertable;
BEGIN
SELECT relname, nspname
INTO STRICT table_name, schema_name
FROM pg_class c
INNER JOIN pg_namespace n ON (n.OID = c.relnamespace)
WHERE c.OID = main_table;

SELECT *
INTO STRICT hypertable_row
FROM _timescaledb_catalog.hypertable h
WHERE h.schema_name = main_block.schema_name
AND h.table_name = main_block.table_name
FOR UPDATE;

PERFORM _timescaledb_internal.add_dimension(main_table,
hypertable_row,
column_name,
number_partitions,
interval_length);
END
$BODY$;

-- Update chunk_time_interval for a hypertable
CREATE OR REPLACE FUNCTION set_chunk_time_interval(
main_table REGCLASS,
Expand Down
128 changes: 97 additions & 31 deletions sql/ddl_internal.sql
Original file line number Diff line number Diff line change
@@ -1,11 +1,10 @@
-- Creates a hypertable row.
CREATE OR REPLACE FUNCTION _timescaledb_internal.create_hypertable_row(
main_table REGCLASS,
schema_name NAME,
table_name NAME,
time_column_name NAME,
time_column_type REGTYPE,
partitioning_column NAME,
partitioning_column_type REGTYPE,
number_partitions INTEGER,
associated_schema_name NAME,
associated_table_prefix NAME,
Expand All @@ -16,10 +15,7 @@ CREATE OR REPLACE FUNCTION _timescaledb_internal.create_hypertable_row(
$BODY$
DECLARE
id INTEGER;
number_dimensions INTEGER = 1;
hypertable_row _timescaledb_catalog.hypertable;
partitioning_func _timescaledb_catalog.dimension.partitioning_func%TYPE = 'get_partition_for_key';
partitioning_func_schema _timescaledb_catalog.dimension.partitioning_func_schema%TYPE = '_timescaledb_internal';
BEGIN
id := nextval(pg_get_serial_sequence('_timescaledb_catalog.hypertable','id'));

Expand All @@ -34,32 +30,21 @@ BEGIN
IF partitioning_column IS NULL THEN
IF number_partitions IS NULL THEN
number_partitions := 1;
partitioning_func := NULL;
partitioning_func_schema := NULL;
ELSIF number_partitions <> 1 THEN
RAISE EXCEPTION 'The number of partitions must be 1 without a partitioning column'
USING ERRCODE ='IO101';
END IF;
ELSIF number_partitions IS NULL THEN
RAISE EXCEPTION 'The number of partitions must be specified when there is a partitioning column'
USING ERRCODE ='IO101';
ELSE
number_dimensions = number_dimensions + 1;
END IF;

IF number_partitions IS NOT NULL AND
(number_partitions < 1 OR number_partitions > 32767) THEN
RAISE EXCEPTION 'Invalid number of partitions'
USING ERRCODE ='IO101';
END IF;

INSERT INTO _timescaledb_catalog.hypertable (
id, schema_name, table_name,
associated_schema_name, associated_table_prefix, num_dimensions)
VALUES (
id, schema_name, table_name,
associated_schema_name, associated_table_prefix,
number_dimensions
associated_schema_name, associated_table_prefix, 1
)
RETURNING * INTO hypertable_row;

Expand All @@ -69,28 +54,109 @@ BEGIN
END IF;

--create time dimension
INSERT INTO _timescaledb_catalog.dimension(hypertable_id, column_name, column_type, aligned,
num_slices, partitioning_func_schema, partitioning_func,
interval_length
) VALUES (
hypertable_row.id, time_column_name, time_column_type, TRUE,
NULL, NULL, NULL,
chunk_time_interval
);
PERFORM _timescaledb_internal.add_dimension(main_table,
hypertable_row,
time_column_name,
NULL,
chunk_time_interval,
FALSE);

IF partitioning_column IS NOT NULL THEN
--create space dimension
INSERT INTO _timescaledb_catalog.dimension(hypertable_id, column_name, column_type, aligned,
PERFORM _timescaledb_internal.add_dimension(main_table,
hypertable_row,
partitioning_column,
number_partitions,
NULL);
END IF;

RETURN hypertable_row;
END
$BODY$;

CREATE OR REPLACE FUNCTION _timescaledb_internal.add_dimension(
main_table REGCLASS,
hypertable_row _timescaledb_catalog.hypertable, -- should be locked FOR UPDATE
column_name NAME,
num_slices INTEGER = NULL,
interval_length BIGINT = NULL,
increment_num_dimensions BOOLEAN = TRUE
)
RETURNS _timescaledb_catalog.dimension LANGUAGE PLPGSQL VOLATILE AS
$BODY$
DECLARE
partitioning_func _timescaledb_catalog.dimension.partitioning_func%TYPE = 'get_partition_for_key';
partitioning_func_schema _timescaledb_catalog.dimension.partitioning_func_schema%TYPE = '_timescaledb_internal';
default_interval BIGINT = _timescaledb_internal.interval_to_usec('1 month');
aligned BOOL;
column_type REGTYPE;
dimension_row _timescaledb_catalog.dimension;
table_has_items BOOLEAN;
BEGIN
IF num_slices IS NULL AND interval_length IS NULL THEN
RAISE EXCEPTION 'The number of slices/partitions or an interval must be specified'
USING ERRCODE = 'IO101';
END IF;

EXECUTE format('SELECT TRUE FROM %s LIMIT 1', main_table) INTO table_has_items;

IF table_has_items THEN
RAISE EXCEPTION 'Cannot add new dimension to a non-empty table'
USING ERRCODE = 'IO102';
END IF;

BEGIN
SELECT atttypid
INTO STRICT column_type
FROM pg_attribute
WHERE attrelid = main_table AND attname = column_name;
EXCEPTION
WHEN NO_DATA_FOUND THEN
RAISE EXCEPTION 'column "%" does not exist', column_name
USING ERRCODE = 'IO102';
END;

IF num_slices IS NULL THEN
-- Open dimension
IF column_type NOT IN ('BIGINT', 'INTEGER', 'SMALLINT', 'TIMESTAMP', 'TIMESTAMPTZ') THEN
RAISE EXCEPTION 'illegal type for column "%": %', column_name, column_type
USING ERRCODE = 'IO102';
END IF;
partitioning_func := NULL;
partitioning_func_schema := NULL;
aligned = TRUE;
ELSE
-- Closed dimension
IF (num_slices < 1 OR num_slices > 32767) THEN
RAISE EXCEPTION 'Invalid number of partitions'
USING ERRCODE ='IO101';
END IF;
aligned = FALSE;
END IF;

BEGIN
INSERT INTO _timescaledb_catalog.dimension(
hypertable_id, column_name, column_type, aligned,
num_slices, partitioning_func_schema, partitioning_func,
interval_length
) VALUES (
hypertable_row.id, partitioning_column, partitioning_column_type, FALSE,
number_partitions::smallint, partitioning_func_schema, partitioning_func,
NULL
);
hypertable_row.id, column_name, column_type, aligned,
num_slices::smallint, partitioning_func_schema, partitioning_func,
interval_length
) RETURNING * INTO dimension_row;
EXCEPTION
WHEN unique_violation THEN
RAISE EXCEPTION 'A dimension on column "%" already exists', column_name
USING ERRCODE = 'IO101';
END;

IF increment_num_dimensions THEN
UPDATE _timescaledb_catalog.hypertable
SET num_dimensions = hypertable_row.num_dimensions + 1
WHERE id = hypertable_row.id;
END IF;

RETURN hypertable_row;
RETURN dimension_row;
END
$BODY$;

Expand Down
3 changes: 2 additions & 1 deletion sql/tables.sql
Original file line number Diff line number Diff line change
Expand Up @@ -79,7 +79,8 @@ CREATE TABLE _timescaledb_catalog.dimension (
CHECK (
(num_slices IS NULL AND interval_length IS NOT NULL) OR
(num_slices IS NOT NULL AND interval_length IS NULL)
)
),
UNIQUE (hypertable_id, column_name)
);
CREATE INDEX ON _timescaledb_catalog.dimension(hypertable_id);
SELECT pg_catalog.pg_extension_config_dump('_timescaledb_catalog.dimension', '');
Expand Down
56 changes: 54 additions & 2 deletions test/expected/create_hypertable.out
Original file line number Diff line number Diff line change
Expand Up @@ -6,7 +6,7 @@ CREATE DATABASE single;
\c single
CREATE EXTENSION IF NOT EXISTS timescaledb;
create schema test_schema;
create table test_schema.test_table(time bigint, temp float8, device_id text);
create table test_schema.test_table(time bigint, temp float8, device_id text, device_type text, location text, id int);
\dt "test_schema".*
List of relations
Schema | Name | Type | Owner
Expand All @@ -20,6 +20,58 @@ select * from create_hypertable('test_schema.test_table', 'time', 'device_id', 2

(1 row)

--test adding one more closed dimension
select add_dimension('test_schema.test_table', 'location', 2);
add_dimension
---------------

(1 row)

select * from _timescaledb_catalog.hypertable where table_name = 'test_table';
id | schema_name | table_name | associated_schema_name | associated_table_prefix | num_dimensions
----+-------------+------------+------------------------+-------------------------+----------------
1 | test_schema | test_table | _timescaledb_internal | _hyper_1 | 3
(1 row)

select * from _timescaledb_catalog.dimension;
id | hypertable_id | column_name | column_type | aligned | num_slices | partitioning_func_schema | partitioning_func | interval_length
----+---------------+-------------+-------------+---------+------------+--------------------------+-----------------------+-----------------
1 | 1 | time | bigint | t | | | | 2592000000000
2 | 1 | device_id | text | f | 2 | _timescaledb_internal | get_partition_for_key |
3 | 1 | location | text | f | 2 | _timescaledb_internal | get_partition_for_key |
(3 rows)

--test adding one more open dimension
select add_dimension('test_schema.test_table', 'id', interval_length => 1000);
add_dimension
---------------

(1 row)

select * from _timescaledb_catalog.hypertable where table_name = 'test_table';
id | schema_name | table_name | associated_schema_name | associated_table_prefix | num_dimensions
----+-------------+------------+------------------------+-------------------------+----------------
1 | test_schema | test_table | _timescaledb_internal | _hyper_1 | 4
(1 row)

select * from _timescaledb_catalog.dimension;
id | hypertable_id | column_name | column_type | aligned | num_slices | partitioning_func_schema | partitioning_func | interval_length
----+---------------+-------------+-------------+---------+------------+--------------------------+-----------------------+-----------------
1 | 1 | time | bigint | t | | | | 2592000000000
2 | 1 | device_id | text | f | 2 | _timescaledb_internal | get_partition_for_key |
3 | 1 | location | text | f | 2 | _timescaledb_internal | get_partition_for_key |
4 | 1 | id | integer | t | | | | 1000
(4 rows)

\set ON_ERROR_STOP 0
--adding the same dimension twice should afail
select add_dimension('test_schema.test_table', 'location', 2);
ERROR: A dimension on column "location" already exists
--adding a new dimension on a non-empty table should also fail
insert into test_schema.test_table values (123456789, 23.8, 'blue', 'type1', 'nyc', 1);
select add_dimension('test_schema.test_table', 'device_type', 2);
ERROR: Cannot add new dimension to a non-empty table
\set ON_ERROR_STOP 1
--test partitioning in only time dimension
create table test_schema.test_1dim(time timestamp, temp float);
select create_hypertable('test_schema.test_1dim', 'time');
Expand Down Expand Up @@ -49,7 +101,7 @@ select create_hypertable('test_schema.test_1dim', 'time');
ERROR: hypertable test_schema.test_1dim already exists
\set ON_ERROR_STOP 1
-- if_not_exist should also work with data in the hypertable
insert into test_schema.test_1dim VALUES ('2004-10-19 10:23:54+02',1.0);
insert into test_schema.test_1dim VALUES ('2004-10-19 10:23:54+02', 1.0);
select create_hypertable('test_schema.test_1dim', 'time', if_not_exists => true);
NOTICE: hypertable test_schema.test_1dim already exists, skipping
create_hypertable
Expand Down
2 changes: 1 addition & 1 deletion test/expected/ddl_errors.out
Original file line number Diff line number Diff line change
Expand Up @@ -20,7 +20,7 @@ ERROR: relation "public.Hypertable_1_mispelled" does not exist at character 33
SELECT * FROM create_hypertable('"public"."Hypertable_1"', 'time_mispelled', 'Device_id', 2);
ERROR: column "time_mispelled" does not exist
SELECT * FROM create_hypertable('"public"."Hypertable_1"', 'Device_id', 'Device_id', 2);
ERROR: illegal type for time column "Device_id": text
ERROR: illegal type for column "Device_id": text
SELECT * FROM create_hypertable('"public"."Hypertable_1"', 'time', 'Device_id_mispelled', 2);
ERROR: column "Device_id_mispelled" does not exist
INSERT INTO PUBLIC."Hypertable_1" VALUES(1,'dev_1', 3);
Expand Down
3 changes: 2 additions & 1 deletion test/expected/extension.out
Original file line number Diff line number Diff line change
Expand Up @@ -18,6 +18,7 @@ WHERE OID IN (
ORDER BY proname;
proname
-------------------------
add_dimension
attach_tablespace
create_hypertable
drop_chunks
Expand All @@ -26,5 +27,5 @@ ORDER BY proname;
restore_timescaledb
set_chunk_time_interval
time_bucket
(8 rows)
(9 rows)

0 comments on commit 696cc4c

Please sign in to comment.