├── Makefile ├── uuidv7-sql.control ├── LICENSE.md ├── README.md └── sql ├── uuidv7-sql--1.0.sql └── uuidv7-sql--1.0--1.1.sql /Makefile: -------------------------------------------------------------------------------- 1 | EXTENSION = uuidv7-sql 2 | EXTVERSION = 1.1 3 | PG_CONFIG = pg_config 4 | 5 | DATA = $(wildcard sql/*.sql) 6 | 7 | PGXS := $(shell $(PG_CONFIG) --pgxs) 8 | include $(PGXS) 9 | -------------------------------------------------------------------------------- /uuidv7-sql.control: -------------------------------------------------------------------------------- 1 | # uuidv7-sql extension 2 | comment = 'Pure SQL functions to handle UUIDs version 7 (see RFC 9562)' 3 | default_version = '1.1' 4 | relocatable = true 5 | superuser = false 6 | -------------------------------------------------------------------------------- /LICENSE.md: -------------------------------------------------------------------------------- 1 | # Copyright and License 2 | 3 | Copyright (c) 2024-2025, Daniel Vérité 4 | 5 | Permission to use, copy, modify, and distribute this software and its documentation for any purpose, without fee, and without a written agreement is hereby granted, provided that the above copyright notice and this paragraph and the following two paragraphs appear in all copies. 6 | 7 | In no event shall Daniel Vérité be liable to any party for direct, indirect, special, incidental, or consequential damages, including lost profits, arising out of the use of this software and its documentation, even if Daniel Vérité has been advised of the possibility of such damage. 8 | 9 | Daniel Vérité specifically disclaims any warranties, including, but not limited to, the implied warranties of merchantability and fitness for a particular purpose. The software provided hereunder is on an "AS IS" basis, and Daniel Vérité has no obligations to provide maintenance, support, updates, enhancements, or modifications. 10 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # postgres-uuidv7-sql 2 | Pure SQL functions to use UUIDs v7 in PostgreSQL. 3 | 4 | The functions are packaged as an extension ("uuidv7-sql") 5 | for convenience, but they may also be created individually 6 | by sourcing all or parts of the [creation scripts](sql/). 7 | 8 | ## Extension installation 9 | The Makefile uses the [PGXS infrastructure](https://www.postgresql.org/docs/current/static/extend-pgxs.html) 10 | 11 | To make the extension available to a PostgreSQL server: 12 | 13 | $ [sudo] make install 14 | 15 | The same, but targeting a specific PostgreSQL installation: 16 | 17 | $ [sudo] make PG_CONFIG=/path/to/pg_config install 18 | 19 | To activate the extension in the target databases: 20 | 21 | CREATE EXTENSION "uuidv7-sql"; 22 | 23 | ## Functions 24 | 25 | ### `uuidv7() -> uuid` 26 | Generate a UUID v7 value using the current time with millisecond precision 27 | and 74 bits of randomness. With PostgreSQL version 18 or newer, 28 | a [built-in function](https://www.postgresql.org/docs/18/functions-uuid.html) with the same name exists in `pg_catalog`, 29 | coming first in the search path. You may prefix `uuidv7` with the schema 30 | (for instance `public.uuidv7()`) to specifically use the version of 31 | this extension, or just use the built-in function instead. 32 | 33 | ### `uuidv7(timestamptz) -> uuid` 34 | Generate a UUID v7 value using the given time with millisecond precision 35 | and 74 bits of randomness. 36 | 37 | ### `uuidv7_sub_ms() -> uuid` 38 | Generate a UUID v7 value using the current time with sub-millisecond 39 | precision (up to 0.25 µs), with 62 bits of randomness. 40 | 41 | ### `uuidv7_sub_ms(timestamptz) -> uuid` 42 | Generate a UUID v7 value using the given time with sub-millisecond 43 | precision (up to 0.25 µs), with 62 bits of randomness. 44 | 45 | ### `uuidv7_extract_timestamp(uuid) -> timestamptz` 46 | Extract the timestamp with millisecond precision from the given UUID v7 value. 47 | 48 | ### `uuidv7_boundary(timestamptz) -> uuid` 49 | Generate a non-random uuidv7 with the given timestamp (first 48 bits) and all random bits to 0. As the smallest possible uuidv7 for that timestamp, it may be used as a boundary for tables partitioned by ranges of UUID. 50 | 51 | ### `uuidv7_encrypt(input uuid, crypt_key bytea, [uuid_ver int]) -> uuid` 52 | Transform a UUID-v7 value into an equivalent UUID-v4 or UUID-v8 (passing 4 or 8 in `uuid_ver`) that does not leak the timestamp. The bit fields `unix_ts_ms` + `rand_a` + 4 more bits (total: 64 bits) from the UUID-v7 value are encrypted with an [XTEA cipher](https://en.wikipedia.org/wiki/XTEA). The 16-byte `crypt_key` parameter is the encryption key. 53 | 54 | ### `uuidv7_decrypt(input uuid, crypt_key bytea) -> uuid` 55 | Decrypt a UUID (either v4 or v8) produced by `uuidv7_encrypt()` with the same `crypt_key`. 56 | -------------------------------------------------------------------------------- /sql/uuidv7-sql--1.0.sql: -------------------------------------------------------------------------------- 1 | /* See the UUID Version 7 specification at 2 | https://www.rfc-editor.org/rfc/rfc9562#name-uuid-version-7 */ 3 | 4 | 5 | /* Main function to generate a uuidv7 value with millisecond precision */ 6 | CREATE FUNCTION uuidv7(timestamptz DEFAULT clock_timestamp()) RETURNS uuid 7 | AS $$ 8 | -- Replace the first 48 bits of a uuidv4 with the current 9 | -- number of milliseconds since 1970-01-01 UTC 10 | -- and set the "ver" field to 7 by setting additional bits 11 | select encode( 12 | set_bit( 13 | set_bit( 14 | overlay(uuid_send(gen_random_uuid()) placing 15 | substring(int8send((extract(epoch from $1)*1000)::bigint) from 3) 16 | from 1 for 6), 17 | 52, 1), 18 | 53, 1), 'hex')::uuid; 19 | $$ LANGUAGE sql volatile parallel safe; 20 | 21 | COMMENT ON FUNCTION uuidv7(timestamptz) IS 22 | 'Generate a uuid-v7 value with a 48-bit timestamp (millisecond precision) and 74 bits of randomness'; 23 | 24 | 25 | /* Version with the "rand_a" field containing sub-milliseconds (method 3 of the spec) 26 | clock_timestamp() is hoped to provide enough precision and consecutive 27 | calls to not happen fast enough to output the same values in that field. 28 | The uuid is the concatenation of: 29 | - 6 bytes with the current Unix timestamp (number of milliseconds since 1970-01-01 UTC) 30 | - 2 bytes with 31 | - 4 bits for the "ver" field 32 | - 12 bits for the fractional part after the milliseconds 33 | - 8 bytes of randomness from the second half of a uuidv4 34 | */ 35 | CREATE FUNCTION uuidv7_sub_ms(timestamptz DEFAULT clock_timestamp()) RETURNS uuid 36 | AS $$ 37 | select encode( 38 | substring(int8send(floor(t_ms)::int8) from 3) || 39 | int2send((7<<12)::int2 | ((t_ms-floor(t_ms))*4096)::int2) || 40 | substring(uuid_send(gen_random_uuid()) from 9 for 8) 41 | , 'hex')::uuid 42 | from (select extract(epoch from $1)*1000 as t_ms) s 43 | $$ LANGUAGE sql volatile parallel safe; 44 | 45 | COMMENT ON FUNCTION uuidv7_sub_ms(timestamptz) IS 46 | 'Generate a uuid-v7 value with a 60-bit timestamp (sub-millisecond precision) and 62 bits of randomness'; 47 | 48 | /* Extract the timestamp in the first 6 bytes of the uuidv7 value. 49 | Use the fact that 'xHHHHH' (where HHHHH are hexadecimal numbers) 50 | can be cast to bit(N) and then to int8. 51 | */ 52 | CREATE FUNCTION uuidv7_extract_timestamp(uuid) RETURNS timestamptz 53 | AS $$ 54 | select to_timestamp( 55 | right(substring(uuid_send($1) from 1 for 6)::text, -1)::bit(48)::int8 -- milliseconds 56 | /1000.0); 57 | $$ LANGUAGE sql immutable strict parallel safe; 58 | 59 | COMMENT ON FUNCTION uuidv7_extract_timestamp(uuid) IS 60 | 'Return the timestamp stored in the first 48 bits of the UUID v7 value'; 61 | 62 | 63 | CREATE FUNCTION uuidv7_boundary(timestamptz) RETURNS uuid 64 | AS $$ 65 | /* uuid fields: version=0b0111, variant=0b10 */ 66 | select encode( 67 | overlay('\x00000000000070008000000000000000'::bytea 68 | placing substring(int8send(floor(extract(epoch from $1) * 1000)::bigint) from 3) 69 | from 1 for 6), 70 | 'hex')::uuid; 71 | $$ LANGUAGE sql stable strict parallel safe; 72 | 73 | COMMENT ON FUNCTION uuidv7_boundary(timestamptz) IS 74 | 'Generate a non-random uuidv7 with the given timestamp (first 48 bits) and all random bits to 0. As the smallest possible uuidv7 for that timestamp, it may be used as a boundary for partitions.'; 75 | -------------------------------------------------------------------------------- /sql/uuidv7-sql--1.0--1.1.sql: -------------------------------------------------------------------------------- 1 | -- \echo Use "ALTER EXTENSION "uuidv7-sql" UPDATE TO '1.1'" to load this file. \quit 2 | 3 | /* 4 | Transform a UUID-v7 value into an equivalent UUID-v4 or UUID-v8 (passing 5 | 4 or 8 in "uuid_ver"), that does not reveal the timestamp. 6 | The fields unix_ts_ms + rand_a + 4 more bits (to reach 64 bits) are encrypted 7 | with an XTEA cipher. The 16-byte "crypt_key" parameter is the encryption key. 8 | */ 9 | CREATE FUNCTION uuidv7_encrypt(input uuid, crypt_key bytea, uuid_ver int default 4) 10 | RETURNS uuid 11 | SET bytea_output to 'hex' 12 | AS $$ 13 | DECLARE 14 | key128 int8[4]; 15 | uuid_parts int8; 16 | v0 int8; 17 | v1 int8; 18 | f_sum int8:=0; 19 | uuid_bits bit(128); 20 | r1 int8; 21 | r2 int8; 22 | rounds constant int:=32; 23 | BEGIN 24 | IF octet_length(crypt_key)<>16 THEN 25 | raise exception 'Encryption key must be 16 bytes long'; 26 | END IF; 27 | /* transfer encryption key into 4x32 bits */ 28 | FOR i IN 1..4 LOOP 29 | key128[i] = right(substring(crypt_key from 1+(i-1)*4 for 4)::text,-1)::bit(32)::int8; 30 | END LOOP; 31 | 32 | uuid_bits = right(uuid_send(input)::text, -1)::bit(128); -- convert \x... to x... 33 | 34 | /* Extract and concatenate the UUID-v7 bit fields to encrypt: 35 | unix_t + 4 arbitrary bits from rand_b + rand_a */ 36 | uuid_parts := (substring(uuid_bits from 1 for 48) || 37 | substring(uuid_bits from 93 for 4) || 38 | substring(uuid_bits from 53 for 12) 39 | )::bit(64)::int8; 40 | 41 | /* encrypt this 64-bit number with an XTEA Feistel network */ 42 | v0 := (uuid_parts>>32)&4294967295; 43 | v1 := uuid_parts&4294967295; 44 | 45 | FOR i in 1..rounds LOOP 46 | v0 := (v0 + (( 47 | ((v1<<4)&4294967295 # (v1>>5)) 48 | + v1)&4294967295 49 | # 50 | (f_sum + key128[1+(f_sum&3)])&4294967295 51 | ))&4294967295; 52 | f_sum := (f_sum + 2654435769) & 4294967295; 53 | v1 := (v1 + (( 54 | ((v0<<4)&4294967295 # (v0>>5)) 55 | + v0)&4294967295 56 | # 57 | (f_sum + key128[1+((f_sum>>11)&3)])&4294967295 58 | ))&4294967295; 59 | END LOOP; /* encrypted value at the end = v0<<32 + v1 */ 60 | 61 | /* Place the bit fields into their final positions */ 62 | r1 := (v0::bit(32) || (v1>>16)::bit(16) || uuid_ver::bit(4) || (v1&4095)::bit(12))::bit(64)::int8; 63 | r2 := (substring(uuid_bits from 65 for 28) || substring(v1::bit(32) from 17 for 4) 64 | || substring(uuid_bits from 97 for 32))::bit(64)::int8; 65 | 66 | RETURN encode(int8send(r1) || int8send(r2), 'hex')::uuid; 67 | END 68 | $$ LANGUAGE plpgsql strict immutable; 69 | 70 | COMMENT ON FUNCTION uuidv7_encrypt(uuid, bytea, int) 71 | IS 'Encrypt a UUID-v7 into an equivalent UUID-v4 or UUID-v8 with an XTEA block cipher'; 72 | 73 | 74 | 75 | /* 76 | Transform a UUID encrypted by encrypt_uuidv7() back to the original 77 | UUID-v7 value. 78 | "crypt_key" must be the same 16-byte key that was used to encrypt. 79 | */ 80 | CREATE FUNCTION uuidv7_decrypt(input uuid, crypt_key bytea) 81 | RETURNS uuid 82 | SET bytea_output to 'hex' 83 | AS $$ 84 | DECLARE 85 | key128 int8[4]; 86 | uuid_parts int8; 87 | v0 int8; 88 | v1 int8; 89 | uuid_bits bit(128); 90 | r1 int8; 91 | r2 int8; 92 | rounds constant int:=32; 93 | f_sum int8 := (2654435769 * rounds)&4294967295; 94 | BEGIN 95 | IF octet_length(crypt_key)<>16 THEN 96 | raise exception 'Encryption key must be 16 bytes long'; 97 | END IF; 98 | /* transfer encryption key into 4x32 bits */ 99 | FOR i IN 1..4 LOOP 100 | key128[i] = right(substring(crypt_key from 1+(i-1)*4 for 4)::text,-1)::bit(32)::int8; 101 | END LOOP; 102 | 103 | uuid_bits = right(uuid_send(input)::text, -1)::bit(128); 104 | 105 | /* Extract and concatenate the UUID-v4 bit fields to decrypt: 106 | random_a + 4 bits from random_c + random_b */ 107 | uuid_parts := (substring(uuid_bits from 1 for 48) || 108 | substring(uuid_bits from 93 for 4) || 109 | substring(uuid_bits from 53 for 12) 110 | )::bit(64)::int8; 111 | 112 | /* decrypt this 64-bit number with an XTEA Feistel network */ 113 | v0 := (uuid_parts>>32)&4294967295; 114 | v1 := uuid_parts&4294967295; 115 | FOR i in 1..32 LOOP 116 | v1 := (v1 - (( 117 | ((v0<<4)&4294967295 # (v0>>5)) 118 | + v0)&4294967295 119 | # 120 | (f_sum + key128[1+((f_sum>>11)&3)])&4294967295 121 | ))&4294967295; 122 | 123 | f_sum := (f_sum - 2654435769)& 4294967295; 124 | 125 | v0 := (v0 - (( 126 | ((v1<<4)&4294967295 # (v1>>5)) 127 | + v1)&4294967295 128 | # 129 | (f_sum + key128[1+(f_sum&3)])&4294967295 130 | ))&4294967295; 131 | END LOOP; 132 | 133 | /* Place the bit fields into their final positions, and set version to 7 */ 134 | r1 := (v0::bit(32) || (v1>>16)::bit(16) || '0111'::bit(4) || (v1&4095)::bit(12))::bit(64)::int8; 135 | r2 := (substring(uuid_bits from 65 for 28) || substring(v1::bit(32) from 17 for 4) 136 | || substring(uuid_bits from 97 for 32))::bit(64)::int8; 137 | 138 | RETURN encode(int8send(r1) || int8send(r2), 'hex')::uuid; 139 | END 140 | $$ LANGUAGE plpgsql strict immutable; 141 | 142 | COMMENT ON FUNCTION uuidv7_decrypt(uuid, bytea) 143 | IS 'Decrypt a UUID produced by uuidv7_encrypt()' 144 | 145 | --------------------------------------------------------------------------------