Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add parse_ulid_timestamp() function #1

Open
wants to merge 2 commits into
base: master
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
1 change: 1 addition & 0 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -27,6 +27,7 @@ A ULID however:

```sql
SELECT generate_ulid(); -- Output: 01D45VGTV648329YZFE7HYVGWC
SELECT parse_ulid_timestamp('01D45VGTV648329YZFE7HYVGWC'); -- Output: 2019-02-20 16:23:49.35+00
```

## Specification
Expand Down
41 changes: 40 additions & 1 deletion pgulid.sql
Original file line number Diff line number Diff line change
Expand Up @@ -18,7 +18,7 @@

CREATE EXTENSION IF NOT EXISTS pgcrypto;

CREATE FUNCTION generate_ulid()
CREATE OR REPLACE FUNCTION generate_ulid()
RETURNS TEXT
AS $$
DECLARE
Expand Down Expand Up @@ -77,3 +77,42 @@ END
$$
LANGUAGE plpgsql
VOLATILE;


CREATE OR REPLACE FUNCTION parse_ulid_timestamp(ulid TEXT) RETURNS TIMESTAMP WITH TIME ZONE
AS $$
DECLARE
-- Crockford's Base32
-- Drop the 0 because strpos() returns 0 for not-found
-- We've pre-validated already, so this is safe
encoding TEXT = '123456789ABCDEFGHJKMNPQRSTVWXYZ';
ts BIGINT;
v CHAR[];
BEGIN
ulid = upper(ulid);

IF NOT ulid ~ '^[0123456789ABCDEFGHJKMNPQRSTVWXYZ]{26}$' THEN
RAISE EXCEPTION 'Invalid ULID: %', ulid;
END IF;

-- first 10 ULID characters are the timestamp
v = regexp_split_to_array(substring(ulid for 10), '');

-- base32 is 5 bits / character
-- posix milliseconds (6 bytes)
ts = (strpos(encoding, v[1])::bigint << 45)
+ (strpos(encoding, v[2])::bigint << 40)
+ (strpos(encoding, v[3])::bigint << 35)
+ (strpos(encoding, v[4])::bigint << 30)
+ (strpos(encoding, v[5]) << 25)
+ (strpos(encoding, v[6]) << 20)
+ (strpos(encoding, v[7]) << 15)
+ (strpos(encoding, v[8]) << 10)
+ (strpos(encoding, v[9]) << 5)
+ strpos(encoding, v[10]);

RETURN to_timestamp(ts / 1000.0);
END
$$
LANGUAGE plpgsql
IMMUTABLE;