├── LICENSE ├── README.md └── ulid.sql /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2016 Matthew Schinckel 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # ulid-postgres 2 | 3 | Still a work in progress. 4 | 5 | See: https://github.com/alizain/ulid 6 | -------------------------------------------------------------------------------- /ulid.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION valid_ulid(TEXT) 2 | RETURNS BOOLEAN AS $$ 3 | SELECT char_length($1) = 26 AND trim('0123456789ABCDEFGHJKMNPQRSTVWXYZ' from upper($1)) = ''; 4 | $$ LANGUAGE SQL IMMUTABLE; 5 | 6 | CREATE OR REPLACE FUNCTION encode_char(INTEGER) 7 | RETURNS char(1) AS $$ 8 | SELECT substring('0123456789ABCDEFGHJKMNPQRSTVWXYZ'::TEXT FROM ($1 + 1) FOR 1); 9 | $$ LANGUAGE SQL IMUTABLE; 10 | 11 | CREATE DOMAIN ulid AS char(26) CHECK (valid_ulid(VALUE)); 12 | 13 | 14 | CREATE OR REPLACE FUNCTION encode_for_ulid(value BIGINT, bytes INTEGER) 15 | RETURNS TEXT AS $$ 16 | WITH RECURSIVE encode(remaining, ulid) AS ( 17 | SELECT $1, ''::TEXT 18 | 19 | UNION 20 | 21 | SELECT remaining / 32, encode_char((remaining % 32)::INTEGER) || ulid 22 | FROM encode 23 | WHERE char_length(ulid) < $2 24 | ) 25 | SELECT ulid FROM encode ORDER BY char_length(ulid) DESC LIMIT 1; 26 | $$ LANGUAGE SQL VOLATILE; 27 | 28 | CREATE OR REPLACE FUNCTION generate_ulid(epoch BIGINT) 29 | RETURNS ulid AS $$ 30 | SELECT (encode_for_ulid(epoch, 10) || encode_for_ulid((random() * 10^16)::BIGINT, 16))::ULID; 31 | $$ LANGUAGE SQL VOLATILE; 32 | 33 | 34 | CREATE OR REPLACE FUNCTION generate_ulid() RETURNS ulid AS $$ 35 | SELECT generate_ulid((EXTRACT(epoch FROM clock_timestamp()) * 1000)::BIGINT); 36 | $$ LANGUAGE SQL VOLATILE; 37 | 38 | 39 | CREATE OR REPLACE FUNCTION decode_chars(TEXT) RETURNS BIGINT AS $$ 40 | WITH RECURSIVE decode(value, index) AS( 41 | SELECT 0::BIGINT, 0 42 | 43 | UNION ALL 44 | 45 | SELECT value + (32^(char_length($1) - index - 1))::BIGINT * ( 46 | position(substring($1 FROM index + 1 FOR 1) IN '0123456789ABCDEFGHJKMNPQRSTVWXYZ'::TEXT) - 1), 47 | index + 1 48 | FROM decode 49 | WHERE index <= char_length($1) + 1 50 | ) 51 | SELECT value::BIGINT FROM decode ORDER BY index DESC LIMIT 1; 52 | $$ LANGUAGE SQL IMMUTABLE; 53 | 54 | 55 | CREATE OR REPLACE FUNCTION seconds(ulid) RETURNS INTEGER AS $$ 56 | SELECT (decode_chars(substring($1::TEXT FROM 1 FOR 10)) / 1000)::INTEGER; 57 | $$ LANGUAGE SQL IMMUTABLE; 58 | 59 | 60 | CREATE OR REPLACE FUNCTION to_tstz(ulid) RETURNS TIMESTAMPTZ AS $$ 61 | SELECT '1970-01-01 00:00:00'::TIMESTAMPTZ + (seconds($1) * INTERVAL '1 second'); 62 | $$ LANGUAGE SQL IMMUTABLE; 63 | 64 | 65 | -- This one doesn't work yet, see below. 66 | CREATE OR REPLACE FUNCTION sharding(ulid, partitions INTEGER) RETURNS BIGINT AS $$ 67 | SELECT decode_chars(substring($1 FROM 10 FOR 16)) % partitions; 68 | $$ LANGUAGE SQL IMMUTABLE; 69 | 70 | 71 | -- Postgres BIGINT is not wide enough for this. 72 | -- NUMERIC seems to give incorrect values, and it's too late to think more. 73 | WITH RECURSIVE decode(value, index, current, power, position) AS( 74 | SELECT 0::NUMERIC, 75 | 0, 76 | NULL::TEXT, 77 | NULL::NUMERIC, 78 | NULL::INTEGER 79 | 80 | UNION ALL 81 | 82 | SELECT value + (32^(16 - index - 1))::NUMERIC * (position(substring('0000053TPJSYAP1D' FROM index + 1 FOR 1) IN '0123456789ABCDEFGHJKMNPQRSTVWXYZ'::TEXT) - 1), 83 | index + 1, 84 | substring('0000053TPJSYAP1D' FROM index + 1 FOR 1), 85 | (32^(16 - index - 1))::NUMERIC, 86 | position(substring('0000053TPJSYAP1D' FROM index + 1 FOR 1) IN '0123456789ABCDEFGHJKMNPQRSTVWXYZ'::TEXT) - 1 87 | FROM decode 88 | WHERE index <= char_length('0000053TPJSYAP1D') 89 | ) 90 | SELECT * FROM decode ORDER BY index LIMIT 100; 91 | --------------------------------------------------------------------------------