Last active
November 17, 2022 21:14
-
-
Save elnygren/68befabdc35e57efb2af8c313a07145a to your computer and use it in GitHub Desktop.
PostgreSQL generate unique sorted IDs for timestamps
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
-- taken from https://rob.conery.io/2014/05/28/a-better-id-generator-for-postgresql/ | |
create schema idgen; | |
create sequence idgen.global_id_sequence; | |
CREATE OR REPLACE FUNCTION idgen.id_generator( | |
myts timestamp, | |
OUT result bigint) AS $$ | |
DECLARE | |
our_epoch bigint := 1314220021721; | |
seq_id bigint; | |
now_millis bigint; | |
-- the id of this DB shard, must be set for each | |
-- schema shard you have - you could pass this as a parameter too | |
shard_id int := 1; | |
BEGIN | |
SELECT nextval('idgen.global_id_sequence') % 1024 INTO seq_id; | |
SELECT FLOOR(EXTRACT(EPOCH FROM myts) * 1000) INTO now_millis; | |
result := (now_millis - our_epoch) << 23; | |
result := result | (shard_id << 10); | |
result := result | (seq_id); | |
END; | |
$$ LANGUAGE PLPGSQL; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
CREATE EXTENSION IF NOT EXISTS pgcrypto; | |
-- Based roughly on: https://github.com/oklog/ulid | |
CREATE OR REPLACE FUNCTION generate_ulid(myts timestamp) | |
RETURNS TEXT | |
AS $$ | |
DECLARE | |
-- Crockford's Base32 | |
encoding BYTEA = '0123456789ABCDEFGHJKMNPQRSTVWXYZ'; | |
timestamp BYTEA = '\\000\\000\\000\\000\\000\\000'; | |
output TEXT = ''; | |
unix_time BIGINT; | |
ulid BYTEA; | |
BEGIN | |
-- 6 timestamp bytes | |
unix_time = (EXTRACT(EPOCH FROM myts) * 1000)::BIGINT; | |
timestamp = SET_BYTE(timestamp, 0, (unix_time >> 40)::BIT(8)::INTEGER); | |
timestamp = SET_BYTE(timestamp, 1, (unix_time >> 32)::BIT(8)::INTEGER); | |
timestamp = SET_BYTE(timestamp, 2, (unix_time >> 24)::BIT(8)::INTEGER); | |
timestamp = SET_BYTE(timestamp, 3, (unix_time >> 16)::BIT(8)::INTEGER); | |
timestamp = SET_BYTE(timestamp, 4, (unix_time >> 8)::BIT(8)::INTEGER); | |
timestamp = SET_BYTE(timestamp, 5, unix_time::BIT(8)::INTEGER); | |
-- 10 entropy bytes | |
ulid = timestamp || gen_random_bytes(10); | |
-- Encode the timestamp | |
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 0) & 224) >> 5)); | |
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 0) & 31))); | |
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 1) & 248) >> 3)); | |
output = output || CHR(GET_BYTE(encoding, ((GET_BYTE(ulid, 1) & 7) << 2) | ((GET_BYTE(ulid, 2) & 192) >> 6))); | |
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 2) & 62) >> 1)); | |
output = output || CHR(GET_BYTE(encoding, ((GET_BYTE(ulid, 2) & 1) << 4) | ((GET_BYTE(ulid, 3) & 240) >> 4))); | |
output = output || CHR(GET_BYTE(encoding, ((GET_BYTE(ulid, 3) & 15) << 1) | ((GET_BYTE(ulid, 4) & 128) >> 7))); | |
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 4) & 124) >> 2)); | |
output = output || CHR(GET_BYTE(encoding, ((GET_BYTE(ulid, 4) & 3) << 3) | ((GET_BYTE(ulid, 5) & 224) >> 5))); | |
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 5) & 31))); | |
-- Encode the entropy | |
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 6) & 248) >> 3)); | |
output = output || CHR(GET_BYTE(encoding, ((GET_BYTE(ulid, 6) & 7) << 2) | ((GET_BYTE(ulid, 7) & 192) >> 6))); | |
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 7) & 62) >> 1)); | |
output = output || CHR(GET_BYTE(encoding, ((GET_BYTE(ulid, 7) & 1) << 4) | ((GET_BYTE(ulid, 8) & 240) >> 4))); | |
output = output || CHR(GET_BYTE(encoding, ((GET_BYTE(ulid, 8) & 15) << 1) | ((GET_BYTE(ulid, 9) & 128) >> 7))); | |
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 9) & 124) >> 2)); | |
output = output || CHR(GET_BYTE(encoding, ((GET_BYTE(ulid, 9) & 3) << 3) | ((GET_BYTE(ulid, 10) & 224) >> 5))); | |
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 10) & 31))); | |
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 11) & 248) >> 3)); | |
output = output || CHR(GET_BYTE(encoding, ((GET_BYTE(ulid, 11) & 7) << 2) | ((GET_BYTE(ulid, 12) & 192) >> 6))); | |
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 12) & 62) >> 1)); | |
output = output || CHR(GET_BYTE(encoding, ((GET_BYTE(ulid, 12) & 1) << 4) | ((GET_BYTE(ulid, 13) & 240) >> 4))); | |
output = output || CHR(GET_BYTE(encoding, ((GET_BYTE(ulid, 13) & 15) << 1) | ((GET_BYTE(ulid, 14) & 128) >> 7))); | |
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 14) & 124) >> 2)); | |
output = output || CHR(GET_BYTE(encoding, ((GET_BYTE(ulid, 14) & 3) << 3) | ((GET_BYTE(ulid, 15) & 224) >> 5))); | |
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 15) & 31))); | |
RETURN output; | |
END | |
$$ | |
LANGUAGE plpgsql | |
VOLATILE; |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment