Skip to content

Instantly share code, notes, and snippets.

@pozs
Last active February 9, 2023 14:33
Show Gist options
  • Save pozs/bd461063489eeca58703 to your computer and use it in GitHub Desktop.
Save pozs/bd461063489eeca58703 to your computer and use it in GitHub Desktop.
Base convert functions for PostgreSQL
-- SQL function to convert numbers from custom bases to numeric
-- requires PostgreSQL 9.3+
CREATE OR REPLACE FUNCTION number_from_base(num TEXT, base INTEGER)
RETURNS NUMERIC
LANGUAGE sql
IMMUTABLE
STRICT
AS $function$
SELECT sum(exp * cn)
FROM (
SELECT base::NUMERIC ^ (row_number() OVER () - 1) exp,
CASE
WHEN ch BETWEEN '0' AND '9' THEN ascii(ch) - ascii('0')
WHEN ch BETWEEN 'a' AND 'z' THEN 10 + ascii(ch) - ascii('a')
END cn
FROM regexp_split_to_table(reverse(lower(num)), '') ch(ch)
) sub
$function$;
-- SQL function to convert bigints to custom bases
-- requires PostgreSQL 9.3+
CREATE OR REPLACE FUNCTION number_to_base(num BIGINT, base INTEGER)
RETURNS TEXT
LANGUAGE sql
IMMUTABLE
STRICT
AS $function$
WITH RECURSIVE n(i, n, r) AS (
SELECT -1, num, 0
UNION ALL
SELECT i + 1, n / base, (n % base)::INT
FROM n
WHERE n > 0
)
SELECT string_agg(ch, '')
FROM (
SELECT CASE
WHEN r BETWEEN 0 AND 9 THEN r::TEXT
WHEN r BETWEEN 10 AND 35 THEN chr(ascii('a') + r - 10)
ELSE '%'
END ch
FROM n
WHERE i >= 0
ORDER BY i DESC
) ch
$function$;
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment