Skip to content

Commit

Permalink
Disable MERGE when using hypertables
Browse files Browse the repository at this point in the history
Fixes timescale#4930

Co-authored-by: Lakshmi Narayanan Sreethar <lakshmi@timescale.com>
  • Loading branch information
Markos Fountoulakis and lkshminarayanan committed Nov 8, 2022
1 parent 2a64450 commit 6298786
Show file tree
Hide file tree
Showing 4 changed files with 225 additions and 0 deletions.
8 changes: 8 additions & 0 deletions src/planner/planner.c
Expand Up @@ -1423,6 +1423,14 @@ replace_hypertable_modify_paths(PlannerInfo *root, List *pathlist, RelOptInfo *i
if (IsA(path, ModifyTablePath))
{
ModifyTablePath *mt = castNode(ModifyTablePath, path);
#if PG15_GE
if (mt->operation == CMD_MERGE)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("The MERGE command does not support hypertables in this version"),
errhint("Check https://github.com/timescale/timescaledb/issues/4929 for"
"more information and current status")));
#endif

#if PG14_GE
/* We only route UPDATE/DELETE through our CustomNode for PG 14+ because
Expand Down
137 changes: 137 additions & 0 deletions test/expected/merge.out
@@ -0,0 +1,137 @@
-- This file and its contents are licensed under the Apache License 2.0.
-- Please see the included NOTICE for copyright information and
-- LICENSE-APACHE for a copy of the license.
-- Create conditions table with location and temperature
DROP TABLE IF EXISTS conditions;
NOTICE: table "conditions" does not exist, skipping
CREATE TABLE conditions (
time TIMESTAMPTZ NOT NULL,
location SMALLINT NOT NULL,
temperature DOUBLE PRECISION NULL
);
SELECT create_hypertable(
'conditions',
'time',
chunk_time_interval => INTERVAL '5 seconds');
create_hypertable
-------------------------
(1,public,conditions,t)
(1 row)


INSERT INTO conditions
SELECT time, location, 14 as temperature
FROM generate_series(
'2021-01-01 00:00:00',
'2021-01-01 00:00:09',
INTERVAL '5 seconds'
) as time,
generate_series(1,4) as location;
-- Create conditions_updated table with location and temperature
DROP TABLE IF EXISTS conditions_updated;
NOTICE: table "conditions_updated" does not exist, skipping
CREATE TABLE conditions_updated (
time TIMESTAMPTZ NOT NULL,
location SMALLINT NOT NULL,
temperature DOUBLE PRECISION NULL
);
SELECT create_hypertable(
'conditions_updated',
'time',
chunk_time_interval => INTERVAL '5 seconds');
create_hypertable
---------------------------------
(2,public,conditions_updated,t)
(1 row)

-- Generate data that overlaps with conditions table
INSERT INTO conditions_updated
SELECT time, location, 80 as temperature
FROM generate_series(
'2021-01-01 00:00:05',
'2021-01-01 00:00:14',
INTERVAL '5 seconds'
) as time,
generate_series(1,4) as location;
-- Print table/rows/num of chunks
select * from conditions order by time, location asc;
time | location | temperature
------------------------------+----------+-------------
Fri Jan 01 00:00:00 2021 PST | 1 | 14
Fri Jan 01 00:00:00 2021 PST | 2 | 14
Fri Jan 01 00:00:00 2021 PST | 3 | 14
Fri Jan 01 00:00:00 2021 PST | 4 | 14
Fri Jan 01 00:00:05 2021 PST | 1 | 14
Fri Jan 01 00:00:05 2021 PST | 2 | 14
Fri Jan 01 00:00:05 2021 PST | 3 | 14
Fri Jan 01 00:00:05 2021 PST | 4 | 14
(8 rows)

select * from conditions_updated order by time, location asc;
time | location | temperature
------------------------------+----------+-------------
Fri Jan 01 00:00:05 2021 PST | 1 | 80
Fri Jan 01 00:00:05 2021 PST | 2 | 80
Fri Jan 01 00:00:05 2021 PST | 3 | 80
Fri Jan 01 00:00:05 2021 PST | 4 | 80
Fri Jan 01 00:00:10 2021 PST | 1 | 80
Fri Jan 01 00:00:10 2021 PST | 2 | 80
Fri Jan 01 00:00:10 2021 PST | 3 | 80
Fri Jan 01 00:00:10 2021 PST | 4 | 80
(8 rows)

select hypertable_name, count(*) as num_of_chunks from timescaledb_information.chunks group by hypertable_name;
hypertable_name | num_of_chunks
--------------------+---------------
conditions | 2
conditions_updated | 2
(2 rows)

-- Print expected values in the conditions table once conditions_updated is merged into it
-- If a key exists in both tables, we take average of the temperature measured
-- average logic here is a mess but it works
SELECT COALESCE(c.time, cu.time) as time,
COALESCE(c.location, cu.location) as location,
(COALESCE(c.temperature, cu.temperature) + COALESCE(cu.temperature, c.temperature))/2 as temperature
FROM conditions AS c FULL JOIN conditions_updated AS cu
ON c.time = cu.time AND c.location = cu.location;
time | location | temperature
------------------------------+----------+-------------
Fri Jan 01 00:00:00 2021 PST | 1 | 14
Fri Jan 01 00:00:00 2021 PST | 2 | 14
Fri Jan 01 00:00:00 2021 PST | 3 | 14
Fri Jan 01 00:00:00 2021 PST | 4 | 14
Fri Jan 01 00:00:05 2021 PST | 1 | 47
Fri Jan 01 00:00:05 2021 PST | 2 | 47
Fri Jan 01 00:00:05 2021 PST | 3 | 47
Fri Jan 01 00:00:05 2021 PST | 4 | 47
Fri Jan 01 00:00:10 2021 PST | 1 | 80
Fri Jan 01 00:00:10 2021 PST | 2 | 80
Fri Jan 01 00:00:10 2021 PST | 3 | 80
Fri Jan 01 00:00:10 2021 PST | 4 | 80
(12 rows)

-- Merge conditions_updated into conditions
\set ON_ERROR_STOP 0
MERGE INTO conditions c
USING conditions_updated cu
ON c.time = cu.time AND c.location = cu.location
WHEN MATCHED THEN
UPDATE SET temperature = (c.temperature + cu.temperature)/2
WHEN NOT MATCHED THEN
INSERT (time, location, temperature) VALUES (cu.time, cu.location, cu.temperature);
ERROR: The MERGE command does not support hypertables in this version
SELECT * FROM conditions ORDER BY time, location ASC;
time | location | temperature
------------------------------+----------+-------------
Fri Jan 01 00:00:00 2021 PST | 1 | 14
Fri Jan 01 00:00:00 2021 PST | 2 | 14
Fri Jan 01 00:00:00 2021 PST | 3 | 14
Fri Jan 01 00:00:00 2021 PST | 4 | 14
Fri Jan 01 00:00:05 2021 PST | 1 | 14
Fri Jan 01 00:00:05 2021 PST | 2 | 14
Fri Jan 01 00:00:05 2021 PST | 3 | 14
Fri Jan 01 00:00:05 2021 PST | 4 | 14
(8 rows)

\set ON_ERROR_STOP 1
4 changes: 4 additions & 0 deletions test/sql/CMakeLists.txt
Expand Up @@ -113,6 +113,10 @@ if((${PG_VERSION_MAJOR} GREATER_EQUAL "14"))
list(APPEND TEST_FILES ddl_extra.sql)
endif()

if((${PG_VERSION_MAJOR} GREATER_EQUAL "15"))
list(APPEND TEST_FILES merge.sql)
endif()

# only test custom type if we are in 64-bit architecture
if("${CMAKE_SIZEOF_VOID_P}" STREQUAL "8")
list(APPEND TEST_FILES custom_type.sql)
Expand Down
76 changes: 76 additions & 0 deletions test/sql/merge.sql
@@ -0,0 +1,76 @@
-- This file and its contents are licensed under the Apache License 2.0.
-- Please see the included NOTICE for copyright information and
-- LICENSE-APACHE for a copy of the license.

-- Create conditions table with location and temperature
DROP TABLE IF EXISTS conditions;
CREATE TABLE conditions (
time TIMESTAMPTZ NOT NULL,
location SMALLINT NOT NULL,
temperature DOUBLE PRECISION NULL
);

SELECT create_hypertable(
'conditions',
'time',
chunk_time_interval => INTERVAL '5 seconds');


INSERT INTO conditions
SELECT time, location, 14 as temperature
FROM generate_series(
'2021-01-01 00:00:00',
'2021-01-01 00:00:09',
INTERVAL '5 seconds'
) as time,
generate_series(1,4) as location;

-- Create conditions_updated table with location and temperature
DROP TABLE IF EXISTS conditions_updated;
CREATE TABLE conditions_updated (
time TIMESTAMPTZ NOT NULL,
location SMALLINT NOT NULL,
temperature DOUBLE PRECISION NULL
);

SELECT create_hypertable(
'conditions_updated',
'time',
chunk_time_interval => INTERVAL '5 seconds');

-- Generate data that overlaps with conditions table
INSERT INTO conditions_updated
SELECT time, location, 80 as temperature
FROM generate_series(
'2021-01-01 00:00:05',
'2021-01-01 00:00:14',
INTERVAL '5 seconds'
) as time,
generate_series(1,4) as location;

-- Print table/rows/num of chunks
select * from conditions order by time, location asc;
select * from conditions_updated order by time, location asc;
select hypertable_name, count(*) as num_of_chunks from timescaledb_information.chunks group by hypertable_name;

-- Print expected values in the conditions table once conditions_updated is merged into it
-- If a key exists in both tables, we take average of the temperature measured
-- average logic here is a mess but it works
SELECT COALESCE(c.time, cu.time) as time,
COALESCE(c.location, cu.location) as location,
(COALESCE(c.temperature, cu.temperature) + COALESCE(cu.temperature, c.temperature))/2 as temperature
FROM conditions AS c FULL JOIN conditions_updated AS cu
ON c.time = cu.time AND c.location = cu.location;

-- Merge conditions_updated into conditions
\set ON_ERROR_STOP 0
MERGE INTO conditions c
USING conditions_updated cu
ON c.time = cu.time AND c.location = cu.location
WHEN MATCHED THEN
UPDATE SET temperature = (c.temperature + cu.temperature)/2
WHEN NOT MATCHED THEN
INSERT (time, location, temperature) VALUES (cu.time, cu.location, cu.temperature);

SELECT * FROM conditions ORDER BY time, location ASC;
\set ON_ERROR_STOP 1

0 comments on commit 6298786

Please sign in to comment.