Skip to content

Commit 9c7191e

Browse files
committed
Change TIMESTAMP partitioning to be completely tz-independent
Previously, for timezones w/o tz. The range_end and range_start were defined as UTC, but the constraints on the table were written as as the local time at the time of chunk creation. This does not work well if timezones change over the life of the hypertable. This change removes the dependency on local time for all timestamp partitioning. Namely, the range_start and range_end remain as UTC but the constraints are now always written in UTC too. Since old constraints correctly describe the data currently in the chunks, the update script to handle this change changes range_start and range_end instead of the constraints. Fixes #300.
1 parent 741b256 commit 9c7191e

File tree

12 files changed

+131
-43
lines changed

12 files changed

+131
-43
lines changed

scripts/test_updates.sh

Lines changed: 4 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -44,8 +44,8 @@ cleanup() {
4444
set +e # do not exit immediately on failure in cleanup handler
4545
if [ $status -eq 0 ]; then
4646
rm -rf ${PGTEST_TMPDIR}
47+
docker rm -vf timescaledb-orig timescaledb-clean-restore timescaledb-updated 2>/dev/null
4748
fi
48-
docker rm -vf timescaledb-orig timescaledb-clean-restore timescaledb-updated 2>/dev/null
4949
echo "Exit status is $status"
5050
exit $status
5151
}
@@ -61,7 +61,7 @@ docker_pgcmd() {
6161
}
6262

6363
docker_pgscript() {
64-
docker_exec $1 "psql -h localhost -U postgres -f $2"
64+
docker_exec $1 "psql -h localhost -U postgres -v ON_ERROR_STOP=1 -f $2"
6565
}
6666

6767
docker_pgtest() {
@@ -78,12 +78,12 @@ docker_pgdiff() {
7878
}
7979

8080
docker_run() {
81-
docker run -d --name $1 -v ${BASE_DIR}:/src $2
81+
docker run -d --name $1 -v ${BASE_DIR}:/src $2 -c timezone="US/Eastern"
8282
wait_for_pg $1
8383
}
8484

8585
docker_run_vol() {
86-
docker run -d --name $1 -v ${BASE_DIR}:/src -v $2 $3
86+
docker run -d --name $1 -v ${BASE_DIR}:/src -v $2 $3 -c timezone="US/Eastern"
8787
wait_for_pg $1
8888
}
8989

sql/updates/post-0.6.1--0.7.0-dev.sql

Lines changed: 18 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -34,3 +34,21 @@ BEGIN
3434
END LOOP;
3535

3636
END$$;
37+
38+
--for timestamp (non-tz) columns we used to have internal_time -> constraint_time via local_time.
39+
--So the internal time was interpreted as UTC but the constraint was printed in terms of the local time.
40+
--Now we interpret the internal_time as UTC and the constraints is generated as UTC as well.
41+
--These constraints should not be re-written since they are correct for the data. But we should adjust the internal time
42+
--to be consistent.
43+
44+
-- So _timescaledb_internal.to_timestamp(internal_time)::timestamp gives you the old constraint
45+
-- We then convert it to timestamptz as though it was at UTC
46+
-- finally, we convert it to the internal represtentation back.
47+
48+
UPDATE _timescaledb_catalog.dimension_slice ds
49+
SET
50+
range_end = _timescaledb_internal.to_unix_microseconds(timezone('UTC',_timescaledb_internal.to_timestamp(range_end)::timestamp)),
51+
range_start = _timescaledb_internal.to_unix_microseconds(timezone('UTC',_timescaledb_internal.to_timestamp(range_start)::timestamp))
52+
FROM _timescaledb_catalog.dimension d
53+
WHERE ds.dimension_id = d.id AND d.column_type = 'timestamp'::regtype;
54+

sql/util_time.sql

Lines changed: 5 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -32,9 +32,12 @@ BEGIN
3232
CASE column_type
3333
WHEN 'BIGINT'::regtype, 'INTEGER'::regtype, 'SMALLINT'::regtype THEN
3434
RETURN format('%L', time_value); -- scale determined by user.
35-
WHEN 'TIMESTAMP'::regtype, 'TIMESTAMPTZ'::regtype THEN
35+
WHEN 'TIMESTAMP'::regtype THEN
36+
--the time_value for timestamps w/o tz does not depend on local timezones. So perform at UTC.
37+
RETURN format('TIMESTAMP %1$L', timezone('UTC',_timescaledb_internal.to_timestamp(time_value))); -- microseconds
38+
WHEN 'TIMESTAMPTZ'::regtype THEN
3639
-- assume time_value is in microsec
37-
RETURN format('%2$s %1$L', _timescaledb_internal.to_timestamp(time_value), column_type); -- microseconds
40+
RETURN format('TIMESTAMPTZ %1$L', _timescaledb_internal.to_timestamp(time_value)); -- microseconds
3841
WHEN 'DATE'::regtype THEN
3942
RETURN format('%L', timezone('UTC',_timescaledb_internal.to_timestamp(time_value))::date);
4043
END CASE;

src/utils.c

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -159,8 +159,8 @@ time_value_to_internal(Datum time_val, Oid type)
159159
}
160160
if (type == TIMESTAMPOID)
161161
{
162-
Datum tz = DirectFunctionCall1(timestamp_timestamptz, time_val);
163-
Datum res = DirectFunctionCall1(pg_timestamp_to_unix_microseconds, tz);
162+
/* for timestamps, ignore timezones, make believe the timestamp is at UTC */
163+
Datum res = DirectFunctionCall1(pg_timestamp_to_unix_microseconds, time_val);
164164

165165
return DatumGetInt64(res);
166166
}

test/expected/ddl_alter_column.out

Lines changed: 3 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -61,7 +61,10 @@ SELECT * FROM alter_test WHERE time > '2017-05-20T10:00:01';
6161

6262
-- rename column and change its type
6363
ALTER TABLE alter_test RENAME COLUMN time TO time_us;
64+
--converting timestamptz->timestamp should happen under UTC
65+
SET timezone = 'UTC';
6466
ALTER TABLE alter_test ALTER COLUMN time_us TYPE timestamp;
67+
RESET timezone;
6568
ALTER TABLE alter_test RENAME COLUMN color TO colorname;
6669
\set ON_ERROR_STOP 0
6770
-- Changing types on hash-partitioned columns is not safe for some

test/expected/insert_single.out

Lines changed: 46 additions & 17 deletions
Original file line numberDiff line numberDiff line change
@@ -242,13 +242,14 @@ SELECT * FROM _timescaledb_catalog.chunk;
242242
5 | 3 | _timescaledb_internal | _hyper_3_5_chunk
243243
6 | 3 | _timescaledb_internal | _hyper_3_6_chunk
244244
7 | 3 | _timescaledb_internal | _hyper_3_7_chunk
245-
9 | 5 | _timescaledb_internal | _hyper_5_9_chunk
246-
10 | 6 | _timescaledb_internal | _hyper_6_10_chunk
245+
8 | 3 | _timescaledb_internal | _hyper_3_8_chunk
246+
10 | 5 | _timescaledb_internal | _hyper_5_10_chunk
247247
11 | 6 | _timescaledb_internal | _hyper_6_11_chunk
248248
12 | 6 | _timescaledb_internal | _hyper_6_12_chunk
249249
13 | 6 | _timescaledb_internal | _hyper_6_13_chunk
250250
14 | 6 | _timescaledb_internal | _hyper_6_14_chunk
251-
(13 rows)
251+
15 | 6 | _timescaledb_internal | _hyper_6_15_chunk
252+
(14 rows)
252253

253254
SELECT * FROM _timescaledb_catalog.dimension_slice;
254255
id | dimension_id | range_start | range_end
@@ -257,16 +258,17 @@ SELECT * FROM _timescaledb_catalog.dimension_slice;
257258
2 | 1 | 1257897600000000000 | 1257900192000000000
258259
3 | 1 | 1257985728000000000 | 1257988320000000000
259260
4 | 2 | 1482624000000000 | 1485216000000000
260-
5 | 3 | -2592000000000 | 0
261-
6 | 3 | 0 | 2592000000000
262-
7 | 3 | -28512000000000 | -25920000000000
263-
9 | 5 | -2581200000000 | -2581199000000
264-
10 | 6 | -20 | -10
265-
11 | 6 | -10 | 0
266-
12 | 6 | 0 | 10
267-
13 | 6 | 10 | 20
268-
14 | 6 | 20 | 30
269-
(13 rows)
261+
5 | 3 | -5184000000000 | -2592000000000
262+
6 | 3 | -2592000000000 | 0
263+
7 | 3 | 0 | 2592000000000
264+
8 | 3 | -28512000000000 | -25920000000000
265+
10 | 5 | -2610000000000 | -2609999000000
266+
11 | 6 | -20 | -10
267+
12 | 6 | -10 | 0
268+
13 | 6 | 0 | 10
269+
14 | 6 | 10 | 20
270+
15 | 6 | 20 | 30
271+
(14 rows)
270272

271273
-- Create a three-dimensional table
272274
CREATE TABLE "3dim" (time timestamp, temp float, device text, location text);
@@ -287,12 +289,12 @@ INSERT INTO "3dim" VALUES('2017-01-20T09:00:01', 22.5, 'blue', 'nyc');
287289
INSERT INTO "3dim" VALUES('2017-01-20T09:00:21', 21.2, 'brown', 'sthlm');
288290
INSERT INTO "3dim" VALUES('2017-01-20T09:00:47', 25.1, 'yellow', 'la');
289291
--show the constraints on the three-dimensional chunk
290-
SELECT * FROM test.show_constraints('_timescaledb_internal._hyper_7_15_chunk');
292+
SELECT * FROM test.show_constraints('_timescaledb_internal._hyper_7_16_chunk');
291293
Constraint | Type | Columns | Index | Expr
292294
---------------+------+------------+-------+----------------------------------------------------------------------------------------------------------------------------------------------
293-
constraint_15 | c | {time} | - | (("time" >= 'Sat Dec 24 16:00:00 2016'::timestamp without time zone) AND ("time" < 'Mon Jan 23 16:00:00 2017'::timestamp without time zone))
294-
constraint_16 | c | {device} | - | (_timescaledb_internal.get_partition_hash(device) < 1073741823)
295-
constraint_17 | c | {location} | - | (_timescaledb_internal.get_partition_hash(location) >= 1073741823)
295+
constraint_16 | c | {time} | - | (("time" >= 'Sun Dec 25 00:00:00 2016'::timestamp without time zone) AND ("time" < 'Tue Jan 24 00:00:00 2017'::timestamp without time zone))
296+
constraint_17 | c | {device} | - | (_timescaledb_internal.get_partition_hash(device) < 1073741823)
297+
constraint_18 | c | {location} | - | (_timescaledb_internal.get_partition_hash(location) >= 1073741823)
296298
(3 rows)
297299

298300
--queries should work in three dimensions
@@ -411,3 +413,30 @@ NOTICE: Adding NOT NULL constraint to time column time (NULL time values not al
411413
SET timezone=+1;
412414
INSERT INTO "hyper_date" VALUES('2011-01-26', 22.5);
413415
RESET timezone;
416+
--make sure timestamp inserts work even when the timezone changes the
417+
SET timezone = 'UTC';
418+
CREATE TABLE "test_tz"(time timestamp PRIMARY KEY, temp float);
419+
SELECT create_hypertable('"test_tz"', 'time', chunk_time_interval=> INTERVAL '1 day');
420+
create_hypertable
421+
-------------------
422+
423+
(1 row)
424+
425+
INSERT INTO "test_tz" VALUES('2017-09-22 10:00:00', 21.2);
426+
INSERT INTO "test_tz" VALUES('2017-09-21 19:00:00', 21.2);
427+
SET timezone = 'US/central';
428+
INSERT INTO "test_tz" VALUES('2017-09-21 19:01:00', 21.2);
429+
SELECT * FROM test.show_constraints('_timescaledb_internal._hyper_10_20_chunk');
430+
Constraint | Type | Columns | Index | Expr
431+
---------------+------+---------+-------+--------------------------------------------------------------------
432+
constraint_23 | c | {time} | - | (("time" >= '01-26-2011'::date) AND ("time" < '02-25-2011'::date))
433+
(1 row)
434+
435+
SELECT * FROM test_tz;
436+
time | temp
437+
--------------------------+------
438+
Fri Sep 22 10:00:00 2017 | 21.2
439+
Thu Sep 21 19:00:00 2017 | 21.2
440+
Thu Sep 21 19:01:00 2017 | 21.2
441+
(3 rows)
442+

test/expected/reindex.out

Lines changed: 5 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -27,13 +27,17 @@ SELECT * FROM test.show_subtables('reindex_test');
2727
_timescaledb_internal._hyper_1_1_chunk
2828
_timescaledb_internal._hyper_1_2_chunk
2929
_timescaledb_internal._hyper_1_3_chunk
30-
(3 rows)
30+
_timescaledb_internal._hyper_1_4_chunk
31+
_timescaledb_internal._hyper_1_5_chunk
32+
(5 rows)
3133

3234
-- show reindexing
3335
REINDEX (VERBOSE) TABLE reindex_test;
3436
INFO: index "_hyper_1_1_chunk_reindex_test_time_unique_idx" was reindexed
3537
INFO: index "_hyper_1_2_chunk_reindex_test_time_unique_idx" was reindexed
3638
INFO: index "_hyper_1_3_chunk_reindex_test_time_unique_idx" was reindexed
39+
INFO: index "_hyper_1_4_chunk_reindex_test_time_unique_idx" was reindexed
40+
INFO: index "_hyper_1_5_chunk_reindex_test_time_unique_idx" was reindexed
3741
\set ON_ERROR_STOP 0
3842
-- this one currently doesn't recurse to chunks and instead gives an
3943
-- error

test/expected/vacuum.out

Lines changed: 9 additions & 9 deletions
Original file line numberDiff line numberDiff line change
@@ -7,12 +7,12 @@ NOTICE: Adding NOT NULL constraint to time column time (NULL time values not al
77

88
(1 row)
99

10-
INSERT INTO vacuum_test VALUES ('2017-01-20T09:00:01', 17.5),
11-
('2017-01-21T09:00:01', 19.1),
12-
('2017-04-20T09:00:01', 89.5),
13-
('2017-04-21T09:00:01', 17.1),
14-
('2017-06-20T09:00:01', 18.5),
15-
('2017-06-21T09:00:01', 11.0);
10+
INSERT INTO vacuum_test VALUES ('2017-01-20T16:00:01', 17.5),
11+
('2017-01-21T16:00:01', 19.1),
12+
('2017-04-20T16:00:01', 89.5),
13+
('2017-04-21T16:00:01', 17.1),
14+
('2017-06-20T16:00:01', 18.5),
15+
('2017-06-21T16:00:01', 11.0);
1616
-- no stats
1717
SELECT tablename, attname, histogram_bounds, n_distinct FROM pg_stats
1818
WHERE schemaname = '_timescaledb_internal' AND tablename LIKE '_hyper_%_chunk'
@@ -43,11 +43,11 @@ WHERE schemaname = '_timescaledb_internal' AND tablename LIKE '_hyper_%_chunk'
4343
ORDER BY schemaname, tablename;
4444
tablename | attname | histogram_bounds | n_distinct
4545
------------------+---------+---------------------------------------------------------+------------
46-
_hyper_1_1_chunk | time | {"Fri Jan 20 09:00:01 2017","Sat Jan 21 09:00:01 2017"} | -1
46+
_hyper_1_1_chunk | time | {"Fri Jan 20 16:00:01 2017","Sat Jan 21 16:00:01 2017"} | -1
4747
_hyper_1_1_chunk | temp | {17.5,19.1} | -1
48-
_hyper_1_2_chunk | time | {"Thu Apr 20 09:00:01 2017","Fri Apr 21 09:00:01 2017"} | -1
48+
_hyper_1_2_chunk | time | {"Thu Apr 20 16:00:01 2017","Fri Apr 21 16:00:01 2017"} | -1
4949
_hyper_1_2_chunk | temp | {17.1,89.5} | -1
50-
_hyper_1_3_chunk | time | {"Tue Jun 20 09:00:01 2017","Wed Jun 21 09:00:01 2017"} | -1
50+
_hyper_1_3_chunk | time | {"Tue Jun 20 16:00:01 2017","Wed Jun 21 16:00:01 2017"} | -1
5151
_hyper_1_3_chunk | temp | {11,18.5} | -1
5252
(6 rows)
5353

test/sql/ddl_alter_column.sql

Lines changed: 3 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -19,7 +19,10 @@ SELECT * FROM alter_test WHERE time > '2017-05-20T10:00:01';
1919

2020
-- rename column and change its type
2121
ALTER TABLE alter_test RENAME COLUMN time TO time_us;
22+
--converting timestamptz->timestamp should happen under UTC
23+
SET timezone = 'UTC';
2224
ALTER TABLE alter_test ALTER COLUMN time_us TYPE timestamp;
25+
RESET timezone;
2326
ALTER TABLE alter_test RENAME COLUMN color TO colorname;
2427
\set ON_ERROR_STOP 0
2528
-- Changing types on hash-partitioned columns is not safe for some

test/sql/insert_single.sql

Lines changed: 13 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -64,7 +64,7 @@ INSERT INTO "3dim" VALUES('2017-01-20T09:00:21', 21.2, 'brown', 'sthlm');
6464
INSERT INTO "3dim" VALUES('2017-01-20T09:00:47', 25.1, 'yellow', 'la');
6565

6666
--show the constraints on the three-dimensional chunk
67-
SELECT * FROM test.show_constraints('_timescaledb_internal._hyper_7_15_chunk');
67+
SELECT * FROM test.show_constraints('_timescaledb_internal._hyper_7_16_chunk');
6868

6969
--queries should work in three dimensions
7070
SELECT * FROM "3dim";
@@ -117,3 +117,15 @@ SELECT create_hypertable('"hyper_date"', 'time');
117117
SET timezone=+1;
118118
INSERT INTO "hyper_date" VALUES('2011-01-26', 22.5);
119119
RESET timezone;
120+
121+
--make sure timestamp inserts work even when the timezone changes the
122+
SET timezone = 'UTC';
123+
CREATE TABLE "test_tz"(time timestamp PRIMARY KEY, temp float);
124+
SELECT create_hypertable('"test_tz"', 'time', chunk_time_interval=> INTERVAL '1 day');
125+
INSERT INTO "test_tz" VALUES('2017-09-22 10:00:00', 21.2);
126+
INSERT INTO "test_tz" VALUES('2017-09-21 19:00:00', 21.2);
127+
SET timezone = 'US/central';
128+
INSERT INTO "test_tz" VALUES('2017-09-21 19:01:00', 21.2);
129+
130+
SELECT * FROM test.show_constraints('_timescaledb_internal._hyper_10_20_chunk');
131+
SELECT * FROM test_tz;

0 commit comments

Comments
 (0)