Skip to content

Instantly share code, notes, and snippets.

@zecho
Forked from fabiolimace/UUIDv6.sql
Created August 18, 2023 11:19
Show Gist options
  • Star 0 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save zecho/d1cadd439cb7134f906be7b9b60489df to your computer and use it in GitHub Desktop.
Save zecho/d1cadd439cb7134f906be7b9b60489df to your computer and use it in GitHub Desktop.
Functions for generating UUIDv6 and UUIDv7 on PostgreSQL
/*
* MIT License
*
* Copyright (c) 2023 Fabio Lima
*
* Permission is hereby granted, free of charge, to any person obtaining a copy
* of this software and associated documentation files (the "Software"), to deal
* in the Software without restriction, including without limitation the rights
* to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
* copies of the Software, and to permit persons to whom the Software is
* furnished to do so, subject to the following conditions:
*
* The above copyright notice and this permission notice shall be included in
* all copies or substantial portions of the Software.
*
* THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
* IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
* FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
* AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
* LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
* OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN
* THE SOFTWARE.
*/
/**
* Returns a time-ordered UUID (UUIDv6).
*
* Referencies:
* - https://github.com/uuid6/uuid6-ietf-draft
* - https://github.com/ietf-wg-uuidrev/rfc4122bis
*
* MIT License.
*
* Tags: uuid guid uuid-generator guid-generator generator time order rfc4122 rfc-4122
*/
create or replace function uuid6() returns uuid as $$
declare
v_time timestamp with time zone:= null;
v_secs bigint := null;
v_usec bigint := null;
v_timestamp bigint := null;
v_timestamp_hex varchar := null;
v_clkseq_and_nodeid bigint := null;
v_clkseq_and_nodeid_hex varchar := null;
v_bytes bytea;
c_epoch bigint := -12219292800; -- RFC-4122 epoch: '1582-10-15 00:00:00'
c_variant bit(64):= x'8000000000000000'; -- RFC-4122 variant: b'10xx...'
begin
-- Get seconds and micros
v_time := clock_timestamp();
v_secs := EXTRACT(EPOCH FROM v_time);
v_usec := mod(EXTRACT(MICROSECONDS FROM v_time)::numeric, 10^6::numeric);
-- Generate timestamp hexadecimal (and set version 6)
v_timestamp := (((v_secs - c_epoch) * 10^6) + v_usec) * 10;
v_timestamp_hex := lpad(to_hex(v_timestamp), 16, '0');
v_timestamp_hex := substr(v_timestamp_hex, 2, 12) || '6' || substr(v_timestamp_hex, 14, 3);
-- Generate clock sequence and node identifier hexadecimal (and set variant b'10xx')
v_clkseq_and_nodeid := ((random()::numeric * 2^62::numeric)::bigint::bit(64) | c_variant)::bigint;
v_clkseq_and_nodeid_hex := lpad(to_hex(v_clkseq_and_nodeid), 16, '0');
-- Concat timestemp, clock sequence and node identifier hexadecimal
v_bytes := decode(v_timestamp_hex || v_clkseq_and_nodeid_hex, 'hex');
return encode(v_bytes, 'hex')::uuid;
end $$ language plpgsql;
-- EXAMPLE:
--
-- select uuid6() uuid, clock_timestamp()-statement_timestamp() time_taken;
-- EXAMPLE OUTPUT:
--
-- |uuid |time_taken |
-- |--------------------------------------|------------------|
-- |1ed58ca7-060a-62a0-aa64-951dd4e5bb8a |00:00:00.000104 |
-------------------------------------------------------------------
-- FOR TEST: the expected result is an empty result set
-------------------------------------------------------------------
-- with t as (
-- select uuid6() as id from generate_series(1, 1000)
-- )
-- select * from t
-- where (id is null or id::text !~ '^[a-f0-9]{8}-[a-f0-9]{4}-6[a-f0-9]{3}-[89ab][a-f0-9]{3}-[a-f0-9]{12}$');
/*
* MIT License
*
* Copyright (c) 2023 Fabio Lima
*
* Permission is hereby granted, free of charge, to any person obtaining a copy
* of this software and associated documentation files (the "Software"), to deal
* in the Software without restriction, including without limitation the rights
* to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
* copies of the Software, and to permit persons to whom the Software is
* furnished to do so, subject to the following conditions:
*
* The above copyright notice and this permission notice shall be included in
* all copies or substantial portions of the Software.
*
* THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
* IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
* FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
* AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
* LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
* OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN
* THE SOFTWARE.
*/
/**
* Returns a time-ordered with Unix Epoch UUID (UUIDv7).
*
* Referencies:
* - https://github.com/uuid6/uuid6-ietf-draft
* - https://github.com/ietf-wg-uuidrev/rfc4122bis
*
* MIT License.
*
* Tags: uuid guid uuid-generator guid-generator generator time order rfc4122 rfc-4122
*/
create or replace function uuid7() returns uuid as $$
declare
v_time timestamp with time zone:= null;
v_secs bigint := null;
v_msec bigint := null;
v_usec bigint := null;
v_timestamp bigint := null;
v_timestamp_hex varchar := null;
v_random bigint := null;
v_random_hex varchar := null;
v_bytes bytea;
c_variant bit(64):= x'8000000000000000'; -- RFC-4122 variant: b'10xx...'
begin
-- Get seconds and micros
v_time := clock_timestamp();
v_secs := EXTRACT(EPOCH FROM v_time);
v_msec := mod(EXTRACT(MILLISECONDS FROM v_time)::numeric, 10^3::numeric);
v_usec := mod(EXTRACT(MICROSECONDS FROM v_time)::numeric, 10^3::numeric);
-- Generate timestamp hexadecimal (and set version 7)
v_timestamp := (((v_secs * 10^3) + v_msec)::bigint << 12) | (v_usec << 2);
v_timestamp_hex := lpad(to_hex(v_timestamp), 16, '0');
v_timestamp_hex := substr(v_timestamp_hex, 2, 12) || '7' || substr(v_timestamp_hex, 14, 3);
-- Generate the random hexadecimal (and set variant b'10xx')
v_random := ((random()::numeric * 2^62::numeric)::bigint::bit(64) | c_variant)::bigint;
v_random_hex := lpad(to_hex(v_random), 16, '0');
-- Concat timestemp and random hexadecimal
v_bytes := decode(v_timestamp_hex || v_random_hex, 'hex');
return encode(v_bytes, 'hex')::uuid;
end $$ language plpgsql;
-- EXAMPLE:
--
-- select uuid7() uuid, clock_timestamp()-statement_timestamp() time_taken;
-- EXAMPLE OUTPUT:
--
-- |uuid |time_taken |
-- |--------------------------------------|------------------|
-- |01878208-432f-7f04-8a23-345dade2b96b |00:00:00.000062 |
-------------------------------------------------------------------
-- FOR TEST: the expected result is an empty result set
-------------------------------------------------------------------
-- with t as (
-- select uuid7() as id from generate_series(1, 1000)
-- )
-- select * from t
-- where (id is null or id::text !~ '^[a-f0-9]{8}-[a-f0-9]{4}-7[a-f0-9]{3}-[89ab][a-f0-9]{3}-[a-f0-9]{12}$');
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment