Skip to content

Commit a6b1694

Browse files
committed
Add UUIDv7 functions
I add a few UUIDv7 related functions so we don't depend on 3rd party extensions for using UUID v7 in timescaledb. This is very useful for testing the UUID compression across pre PG v18.
1 parent 93c74c9 commit a6b1694

File tree

13 files changed

+288
-0
lines changed

13 files changed

+288
-0
lines changed

.github/gh_matrix_builder.py

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -51,6 +51,7 @@
5151
"bgw_launcher",
5252
"telemetry",
5353
"memoize",
54+
"net",
5455
}
5556

5657
# Tests that we do not run as part of a Flake tests

.github/workflows/linux-32bit-build-and-test.yaml

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -59,6 +59,7 @@ jobs:
5959
compress_bloom_sparse_debug
6060
compress_qualpushdown_saop
6161
compression_allocation
62+
net
6263
pg_dump
6364
telemetry
6465
transparent_decompress_chunk-*

.github/workflows/windows-build-and-test.yaml

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -79,6 +79,7 @@ jobs:
7979
compress_qualpushdown_saop
8080
compressed_copy
8181
compression_algos
82+
compression_uuid
8283
bgw_launcher
8384
chunk_adaptive
8485
metadata

.unreleased/pr_8385

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1 @@
1+
Implements: #8385 UUID v7 functions for testing pre PG18

cmake/ScriptFiles.cmake

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -42,6 +42,7 @@ set(SOURCE_FILES
4242
histogram.sql
4343
bgw_scheduler.sql
4444
metadata.sql
45+
uuidv7.sql
4546
views.sql
4647
views_experimental.sql
4748
gapfill.sql

sql/updates/reverse-dev.sql

Lines changed: 4 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -96,3 +96,7 @@ _timescaledb_functions.policy_compression_execute(
9696
useam BOOLEAN = NULL)
9797
AS $$ BEGIN END $$ LANGUAGE PLPGSQL;
9898

99+
DROP FUNCTION IF EXISTS _timescaledb_functions.generate_uuid_v7;
100+
DROP FUNCTION IF EXISTS _timescaledb_functions.uuid_v7_from_timestamptz;
101+
DROP FUNCTION IF EXISTS _timescaledb_functions.timestamptz_from_uuid_v7;
102+
DROP FUNCTION IF EXISTS _timescaledb_functions.uuid_version;

sql/uuidv7.sql

Lines changed: 22 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,22 @@
1+
-- This file and its contents are licensed under the Apache License 2.0.
2+
-- Please see the included NOTICE for copyright information and
3+
-- LICENSE-APACHE for a copy of the license.
4+
5+
CREATE OR REPLACE FUNCTION _timescaledb_functions.generate_uuid_v7() RETURNS UUID
6+
AS '@MODULE_PATHNAME@', 'ts_uuid_generate_v7' LANGUAGE C VOLATILE STRICT;
7+
8+
CREATE OR REPLACE FUNCTION _timescaledb_functions.uuid_v7_from_timestamptz(
9+
ts TIMESTAMPTZ
10+
) RETURNS UUID
11+
AS '@MODULE_PATHNAME@', 'ts_uuid_v7_from_timestamptz' LANGUAGE C VOLATILE STRICT;
12+
13+
CREATE OR REPLACE FUNCTION _timescaledb_functions.timestamptz_from_uuid_v7(
14+
uuid UUID
15+
) RETURNS TIMESTAMPTZ
16+
AS '@MODULE_PATHNAME@', 'ts_timestamptz_from_uuid_v7' LANGUAGE C STRICT;
17+
18+
CREATE OR REPLACE FUNCTION _timescaledb_functions.uuid_version(
19+
uuid UUID
20+
) RETURNS INTEGER
21+
AS '@MODULE_PATHNAME@', 'ts_uuid_version' LANGUAGE C STRICT;
22+

src/uuid.c

Lines changed: 97 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -4,6 +4,7 @@
44
* LICENSE-APACHE for a copy of the license.
55
*/
66
#include <postgres.h>
7+
#include <port/pg_bswap.h>
78
#include <utils/timestamp.h>
89
#include <utils/uuid.h>
910

@@ -54,3 +55,99 @@ ts_uuid_generate(PG_FUNCTION_ARGS)
5455
{
5556
return UUIDPGetDatum(ts_uuid_create());
5657
}
58+
59+
pg_uuid_t *
60+
ts_create_uuid_v7_from_timestamptz(TimestampTz ts)
61+
{
62+
/*
63+
* TimestampTz is a 64bit integer, counting the microseconds from 2000-01-01.
64+
* The UUID v7 format uses the first 48 bits for the timestamp, that represents
65+
* the number of milliseconds since 1970-01-01.
66+
*/
67+
68+
/* Difference in milliseconds between 2000-01-01 and 1970-01-01 */
69+
int64 epoch_diff_millis =
70+
((int64) (POSTGRES_EPOCH_JDATE - UNIX_EPOCH_JDATE) * SECS_PER_DAY) * 1000ULL;
71+
int64 epoch_millis = (ts / 1000) + epoch_diff_millis;
72+
73+
/* The microseconds part of the timestamp, scaled to 12 bits, same as in PG18 */
74+
uint32 ts_micros = (ts % 1000) * (1 << 12) / 1000;
75+
76+
uint64_t timestamp_be = pg_hton64(epoch_millis << 16);
77+
pg_uuid_t *uuid = (pg_uuid_t *) palloc0(sizeof(pg_uuid_t));
78+
79+
pg_backend_random((char *) uuid, UUID_LEN);
80+
81+
/* Overwrite the first 48 bits with the timestamp */
82+
memcpy(uuid->data, &timestamp_be, 6);
83+
84+
/*
85+
* Sub milliseconds timestamps are optional. We store the microseconds part in the
86+
* rand_a field as described in the UUID v7 specification. Following the PG18 logic
87+
* here.
88+
*/
89+
uuid->data[6] = (unsigned char) (ts_micros >> 8);
90+
uuid->data[7] = (unsigned char) ts_micros;
91+
92+
/* Set version 7 (0111) in bits 6-7 of byte 6, keep random bits 0-5 */
93+
uuid->data[6] = (uuid->data[6] & 0x0F) | 0x70;
94+
95+
/* Set variant (10) in bits 4-5 of byte 8, keep random bits 0-3 and 6-7 */
96+
uuid->data[8] = (uuid->data[8] & 0x3F) | 0x80;
97+
98+
return uuid;
99+
}
100+
101+
TS_FUNCTION_INFO_V1(ts_uuid_generate_v7);
102+
103+
Datum
104+
ts_uuid_generate_v7(PG_FUNCTION_ARGS)
105+
{
106+
return UUIDPGetDatum(ts_create_uuid_v7_from_timestamptz(GetCurrentTimestamp()));
107+
}
108+
109+
TS_FUNCTION_INFO_V1(ts_uuid_v7_from_timestamptz);
110+
111+
Datum
112+
ts_uuid_v7_from_timestamptz(PG_FUNCTION_ARGS)
113+
{
114+
TimestampTz timestamp = PG_GETARG_TIMESTAMPTZ(0);
115+
return UUIDPGetDatum(ts_create_uuid_v7_from_timestamptz(timestamp));
116+
}
117+
118+
TS_FUNCTION_INFO_V1(ts_timestamptz_from_uuid_v7);
119+
120+
Datum
121+
ts_timestamptz_from_uuid_v7(PG_FUNCTION_ARGS)
122+
{
123+
pg_uuid_t *uuid = PG_GETARG_UUID_P(0);
124+
125+
/* Big endian timestamp in milliseconds from Unix Epoch */
126+
uint64 timestamp_be = 0;
127+
memcpy(&timestamp_be, uuid->data, 6);
128+
129+
/* The timestamp is now milliseconds from Unix Epoch (1970-01-01)*/
130+
uint64 timestamp = (pg_ntoh64(timestamp_be)) >> 16;
131+
132+
/* Get the sub ms part as well, reversing the scaling */
133+
uint32 subms_timestamp = ((uuid->data[6] << 8) | uuid->data[7]) * 1000 / (1 << 12);
134+
135+
/* Milliseconds timestamp from PG Epoch (2000-01-01) */
136+
uint64 timestamp_micros =
137+
(timestamp - ((uint64) (POSTGRES_EPOCH_JDATE - UNIX_EPOCH_JDATE) * SECS_PER_DAY) * 1000ULL);
138+
139+
/* Add up the whole to get microseconds */
140+
TimestampTz ts = timestamp_micros * 1000 + subms_timestamp;
141+
142+
return TimestampTzGetDatum(ts);
143+
}
144+
145+
TS_FUNCTION_INFO_V1(ts_uuid_version);
146+
147+
Datum
148+
ts_uuid_version(PG_FUNCTION_ARGS)
149+
{
150+
pg_uuid_t *uuid = PG_GETARG_UUID_P(0);
151+
int version = (uuid->data[6] & 0xf0) >> 4; /* Get the version from the UUID */
152+
PG_RETURN_INT32(version);
153+
}

src/uuid.h

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -9,3 +9,4 @@
99
#include <utils/uuid.h>
1010

1111
extern pg_uuid_t *ts_uuid_create(void);
12+
extern pg_uuid_t *ts_create_uuid_v7_from_timestamptz(TimestampTz ts);
Lines changed: 80 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,80 @@
1+
-- This file and its contents are licensed under the Timescale License.
2+
-- Please see the included NOTICE for copyright information and
3+
-- LICENSE-TIMESCALE for a copy of the license.
4+
--install necessary functions for tests
5+
\c :TEST_DBNAME :ROLE_DEFAULT_PERM_USER
6+
-- The first hundred elements are generated with the Go uuid v7 routines
7+
CREATE TABLE uuids (i int, u uuid);
8+
INSERT INTO uuids (i, u) VALUES
9+
(1, '0197a7a9-b48b-7c70-be05-e376afc66ee1'), (2, '0197a7a9-b48b-7c71-92cb-eb724822bb0f'), (3, '0197a7a9-b48b-7c72-bd57-49f981f064fd'), (4, '0197a7a9-b48b-7c73-b521-91172c2e770a'),
10+
(5, '0197a7a9-b48b-7c74-a2a4-dcdbce635d11'), (6, '0197a7a9-b48b-7c75-a810-8acf630e634f'), (7, '0197a7a9-b48b-7c76-b616-69e64a802b5c'), (8, '0197a7a9-b48b-7c77-b54f-c5f3d64d68d0'),
11+
(9, '0197a7a9-b48b-7c78-ab14-78b3dd81dbbc'), (10, '0197a7a9-b48b-7c79-92c7-7dde3bea6252'), (11, '0197a7a9-b48b-7c7a-8d9e-5afc3bf15234'), (12, '0197a7a9-b48b-7c7b-bc49-7150f16d8d63'),
12+
(13, '0197a7a9-b48b-7c7c-aa7a-60d47bf04ff8'), (14, '0197a7a9-b48b-7c7d-8cfe-9503ed9bb1c9'), (15, '0197a7a9-b48b-7c7e-9ebb-acf63f5b625e'), (16, '0197a7a9-b48b-7c7f-a0c1-ba4adf950a2a'),
13+
(17, '0197a7a9-b48b-7c80-a534-4eda33d89b41'), (18, '0197a7a9-b48b-7c81-abaf-e4d27888f6ea'), (19, '0197a7a9-b48b-7c82-a07c-bb5278039b67'), (20, '0197a7a9-b48b-7c83-9df3-2826632fcb42'),
14+
(21, '0197a7a9-b48b-7c84-8588-dc4e6f10a5be'), (22, '0197a7a9-b48b-7c85-98a4-5ba69598ba88'), (23, '0197a7a9-b48b-7c86-9a96-69906846edf4'), (24, '0197a7a9-b48b-7c87-843a-d0c409e538d2'),
15+
(25, '0197a7a9-b48b-7c88-a9c9-8e03283979dd'), (26, '0197a7a9-b48c-7c88-b962-5f38a5f5bb19'), (27, '0197a7a9-b48c-7c89-ad12-19c425cfe319'), (28, '0197a7a9-b48c-7c8a-9652-43b070f806b6'),
16+
(29, '0197a7a9-b48c-7c8b-8b95-2e4b27b7c359'), (30, '0197a7a9-b48c-7c8c-9230-5a1b6a126d4e'), (31, '0197a7a9-b48c-7c8d-98e9-3622fe1418ae'), (32, '0197a7a9-b48c-7c8e-b262-e91dcf84f985'),
17+
(33, '0197a7a9-b48c-7c8f-90c0-1036d19e438e'), (34, '0197a7a9-b48c-7c90-9fcb-f092518ae1e6'), (35, '0197a7a9-b48c-7c91-bf68-433e366f751d'), (36, '0197a7a9-b48c-7c92-95b6-82cb29498e5a'),
18+
(37, '0197a7a9-b48c-7c93-9397-6ebbb9d4194d'), (38, '0197a7a9-b48c-7c94-8484-f47122e2dea3'), (39, '0197a7a9-b48c-7c95-a6e5-fe8d062f4e3c'), (40, '0197a7a9-b48c-7c96-914c-690b7930262f'),
19+
(41, '0197a7a9-b48c-7c97-ac2b-473d61e0c396'), (42, '0197a7a9-b48c-7c98-93bd-ca093b30f6e8'), (43, '0197a7a9-b48c-7c99-b906-7fa2180536d3'), (44, '0197a7a9-b48c-7c9a-a090-fe01428ccefc'),
20+
(45, '0197a7a9-b48c-7c9b-9319-de9dd58deeee'), (46, '0197a7a9-b48c-7c9c-a9d4-ed6f3e6a41b7'), (47, '0197a7a9-b48c-7c9d-8036-4141e0780323'), (48, '0197a7a9-b48c-7c9e-bfbe-f00eb49ed7f2'),
21+
(49, '0197a7a9-b48c-7c9f-8ffe-71cf00a0c0c0'), (50, '0197a7a9-b48c-7ca0-822f-95ced2f95702'), (51, '0197a7a9-b48c-7ca1-8c8a-66582aec95fa'), (52, '0197a7a9-b48c-7ca2-95c3-fe80362a2251'),
22+
(53, '0197a7a9-b48c-7ca3-855f-f681b254a8c8'), (54, '0197a7a9-b48c-7ca4-856b-a562eca93c3f'), (55, '0197a7a9-b48c-7ca5-a30e-37c247fb4c46'), (56, '0197a7a9-b48c-7ca6-9e78-a148d54a44ac'),
23+
(57, '0197a7a9-b48c-7ca7-badb-4b650bf5bf5f'), (58, '0197a7a9-b48c-7ca8-8275-a8590869ef13'), (59, '0197a7a9-b48c-7ca9-b328-b54c3901223c'), (60, '0197a7a9-b48c-7caa-a15d-f5564e4e552c'),
24+
(61, '0197a7a9-b48c-7cab-a4ac-017259746322'), (62, '0197a7a9-b48c-7cac-bda5-74ef12abd6b8'), (63, '0197a7a9-b48c-7cad-a3cd-0e4c93eaba80'), (64, '0197a7a9-b48c-7cae-9667-de4a226418df'),
25+
(65, '0197a7a9-b48c-7caf-8aa2-067619170f32'), (66, '0197a7a9-b48c-7cb0-ba8c-91d9e8920845'), (67, '0197a7a9-b48c-7cb1-9681-a62bfffe9237'), (68, '0197a7a9-b48c-7cb2-b78b-037e5ee26ff6'),
26+
(69, '0197a7a9-b48c-7cb3-ac27-e24382445188'), (70, '0197a7a9-b48b-7c7d-8cfe-9503ed9bb1c9'), (71, '0197a7a9-b48b-7c7e-9ebb-acf63f5b625e'), (72, '0197a7a9-b48b-7c7f-a0c1-ba4adf950a2a'),
27+
(73, '0197a7a9-b48b-7c80-a534-4eda33d89b41'), (74, '0197a7a9-b48b-7c81-abaf-e4d27888f6ea'), (75, '0197a7a9-b48b-7c82-a07c-bb5278039b67'), (76, '0197a7a9-b48b-7c83-9df3-2826632fcb42'),
28+
(77, '0197a7a9-b48b-7c84-8588-dc4e6f10a5be'), (78, '0197a7a9-b48b-7c85-98a4-5ba69598ba88'), (79, '0197a7a9-b48b-7c86-9a96-69906846edf4'), (80, '0197a7a9-b48b-7c87-843a-d0c409e538d2'),
29+
(81, '0197a7a9-b48b-7c88-a9c9-8e03283979dd'), (82, '0197a7a9-b48c-7c88-b962-5f38a5f5bb19'), (83, '0197a7a9-b48c-7c89-ad12-19c425cfe319'), (84, '0197a7a9-b48c-7c8a-9652-43b070f806b6'),
30+
(85, '0197a7a9-b48c-7c8b-8b95-2e4b27b7c359'), (86, '0197a7a9-b48c-7c8c-9230-5a1b6a126d4e'), (87, '0197a7a9-b48c-7c8d-98e9-3622fe1418ae'), (88, '0197a7a9-b48c-7c8e-b262-e91dcf84f985'),
31+
(89, '0197a7a9-b48c-7c8f-90c0-1036d19e438e'), (90, '0197a7a9-b48c-7c90-9fcb-f092518ae1e6'), (91, '0197a7a9-b48c-7c91-bf68-433e366f751d'), (92, '0197a7a9-b48c-7c92-95b6-82cb29498e5a'),
32+
(93, '0197a7a9-b48c-7c93-9397-6ebbb9d4194d'), (94, '0197a7a9-b48c-7c94-8484-f47122e2dea3'), (95, '0197a7a9-b48c-7c95-a6e5-fe8d062f4e3c'), (96, '0197a7a9-b48c-7c96-914c-690b7930262f'),
33+
(97, '0197a7a9-b48c-7c97-ac2b-473d61e0c396'), (98, '0197a7a9-b48c-7c98-93bd-ca093b30f6e8'), (99, '0197a7a9-b48c-7c99-b906-7fa2180536d3'), (100, '0197a7a9-b48c-7c9a-a090-fe01428ccefc');
34+
-- The next 3 items are generated with the new functions
35+
INSERT INTO uuids VALUES (101, _timescaledb_functions.uuid_v7_from_timestamptz('2025-07-02:03:04:05'::timestamptz));
36+
INSERT INTO uuids VALUES (102, _timescaledb_functions.uuid_v7_from_timestamptz('2029-01-02:03:04:05'::timestamptz));
37+
INSERT INTO uuids VALUES (103, _timescaledb_functions.uuid_v7_from_timestamptz('2059-02-03:04:05:06'::timestamptz));
38+
INSERT INTO uuids VALUES (104, _timescaledb_functions.uuid_v7_from_timestamptz('2100-07-08:09:10:11'::timestamptz));
39+
SELECT
40+
to_char(_timescaledb_functions.timestamptz_from_uuid_v7(u), 'YYYY-MM-DD:HH24:MI:SS'),
41+
_timescaledb_functions.uuid_version(u),
42+
count(*)
43+
FROM
44+
uuids
45+
GROUP BY 1,2
46+
ORDER BY 1,2;
47+
to_char | uuid_version | count
48+
---------------------+--------------+-------
49+
2025-06-25:08:16:46 | 7 | 100
50+
2025-07-02:03:04:05 | 7 | 1
51+
2029-01-02:03:04:05 | 7 | 1
52+
2059-02-03:04:05:06 | 7 | 1
53+
2100-07-08:09:10:11 | 7 | 1
54+
(5 rows)
55+
56+
-- Add some v4 timestamps for sanity check
57+
INSERT INTO uuids VALUES (105, _timescaledb_functions.generate_uuid());
58+
INSERT INTO uuids VALUES (106, _timescaledb_functions.generate_uuid());
59+
INSERT INTO uuids VALUES (107, _timescaledb_functions.generate_uuid());
60+
-- Add some random v7 timestamps too
61+
INSERT INTO uuids VALUES (108, _timescaledb_functions.generate_uuid_v7());
62+
INSERT INTO uuids VALUES (109, _timescaledb_functions.generate_uuid_v7());
63+
INSERT INTO uuids VALUES (110, _timescaledb_functions.generate_uuid_v7());
64+
-- The version numbers should make sense
65+
SELECT
66+
_timescaledb_functions.uuid_version(u),
67+
count(*)
68+
FROM
69+
uuids
70+
WHERE
71+
-- The filters are here just to test, they don't blow up with random data from v4
72+
_timescaledb_functions.timestamptz_from_uuid_v7(u) > '2000-01-01:01:01:01'::timestamptz
73+
GROUP BY 1
74+
ORDER BY 1;
75+
uuid_version | count
76+
--------------+-------
77+
4 | 3
78+
7 | 107
79+
(2 rows)
80+

0 commit comments

Comments
 (0)