Skip to content

Commit

Permalink
Add test for GiST exclusion constraint on chunk
Browse files Browse the repository at this point in the history
  • Loading branch information
mkindahl committed Nov 28, 2024
1 parent 316e7c2 commit 186f7a4
Show file tree
Hide file tree
Showing 2 changed files with 93 additions and 2 deletions.
48 changes: 47 additions & 1 deletion tsl/test/expected/hypercore_constraints.out
Original file line number Diff line number Diff line change
@@ -1,7 +1,7 @@
-- This file and its contents are licensed under the Timescale License.
-- Please see the included NOTICE for copyright information and
-- LICENSE-TIMESCALE for a copy of the license.
\c :TEST_DBNAME :ROLE_DEFAULT_PERM_USER;
\c :TEST_DBNAME :ROLE_SUPERUSER;
\ir include/setup_hypercore.sql
-- This file and its contents are licensed under the Timescale License.
-- Please see the included NOTICE for copyright information and
Expand Down Expand Up @@ -139,3 +139,49 @@ insert into :chunk1(created_at, location_id, device_id, owner_id, temp, humidity
select created_at, location_id, device_id, owner_id, temp, humidity from sample;
ERROR: conflicting key value violates exclusion constraint "1_7_readings_created_at_excl"
\set ON_ERROR_STOP 0
create table test_exclude(
created_at timestamptz not null unique,
device_id bigint,
humidity numrange
);
select create_hypertable('test_exclude', by_range('created_at'));
create_hypertable
-------------------
(3,t)
(1 row)

create or replace function randrange() returns numrange as $$
declare
start numeric := 100.0 * random()::numeric;
begin
return numrange(start, start + random()::numeric);
end;
$$ language plpgsql;
-- Insert a bunch or rows with a random humidity range.
insert into test_exclude (created_at, device_id, humidity)
select ts, ceil(random()*30), randrange()
from generate_series('2022-06-01'::timestamptz, '2022-07-01', '5m') ts;
-- Pick a chunk to work with.
select exclude_chunk from show_chunks('test_exclude') tbl(exclude_chunk) limit 1 \gset
-- Find all rows that is a duplicate of a previous row.
select * into dups from :exclude_chunk o where (
select count(*)
from :exclude_chunk i
where i.created_at < o.created_at and i.humidity && o.humidity
) > 0;
-- Make sure we have some duplicates. Otherwise, the test does not work.
select count(*) > 0 from dups;
?column?
----------
t
(1 row)

-- Delete the duplicates.
delete from :exclude_chunk where created_at in (select created_at from dups);
-- Add an exclusion constraint.
alter table :exclude_chunk add constraint humidity_overlap exclude using gist (humidity with &&);
-- Make sure that inserting some duplicate fails on this the exclusion constraint.
\set ON_ERROR_STOP 0
insert into :exclude_chunk select * from dups limit 10;
ERROR: conflicting key value violates exclusion constraint "humidity_overlap"
\set ON_ERROR_STOP 1
47 changes: 46 additions & 1 deletion tsl/test/sql/hypercore_constraints.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2,7 +2,7 @@
-- Please see the included NOTICE for copyright information and
-- LICENSE-TIMESCALE for a copy of the license.

\c :TEST_DBNAME :ROLE_DEFAULT_PERM_USER;
\c :TEST_DBNAME :ROLE_SUPERUSER;

\ir include/setup_hypercore.sql

Expand Down Expand Up @@ -32,3 +32,48 @@ select created_at, location_id, device_id, owner_id, temp, humidity from sample;
insert into :chunk1(created_at, location_id, device_id, owner_id, temp, humidity)
select created_at, location_id, device_id, owner_id, temp, humidity from sample;
\set ON_ERROR_STOP 0

create table test_exclude(
created_at timestamptz not null unique,
device_id bigint,
humidity numrange
);

select create_hypertable('test_exclude', by_range('created_at'));

create or replace function randrange() returns numrange as $$
declare
start numeric := 100.0 * random()::numeric;
begin
return numrange(start, start + random()::numeric);
end;
$$ language plpgsql;

-- Insert a bunch or rows with a random humidity range.
insert into test_exclude (created_at, device_id, humidity)
select ts, ceil(random()*30), randrange()
from generate_series('2022-06-01'::timestamptz, '2022-07-01', '5m') ts;

-- Pick a chunk to work with.
select exclude_chunk from show_chunks('test_exclude') tbl(exclude_chunk) limit 1 \gset

-- Find all rows that is a duplicate of a previous row.
select * into dups from :exclude_chunk o where (
select count(*)
from :exclude_chunk i
where i.created_at < o.created_at and i.humidity && o.humidity
) > 0;

-- Make sure we have some duplicates. Otherwise, the test does not work.
select count(*) > 0 from dups;

-- Delete the duplicates.
delete from :exclude_chunk where created_at in (select created_at from dups);

-- Add an exclusion constraint.
alter table :exclude_chunk add constraint humidity_overlap exclude using gist (humidity with &&);

-- Make sure that inserting some duplicate fails on this the exclusion constraint.
\set ON_ERROR_STOP 0
insert into :exclude_chunk select * from dups limit 10;
\set ON_ERROR_STOP 1

0 comments on commit 186f7a4

Please sign in to comment.