mirror of
https://github.com/jbranchaud/til
synced 2026-01-03 07:08:01 +00:00
Add Generate Random Alphanumeric Identifier as a Postgres TIL
This commit is contained in:
@@ -10,7 +10,7 @@ pairing with smart people at Hashrocket.
|
||||
|
||||
For a steady stream of TILs, [sign up for my newsletter](https://crafty-builder-6996.ck.page/e169c61186).
|
||||
|
||||
_1492 TILs and counting..._
|
||||
_1493 TILs and counting..._
|
||||
|
||||
---
|
||||
|
||||
@@ -771,6 +771,7 @@ _1492 TILs and counting..._
|
||||
- [Force SSL When Making A psql Connection](postgres/force-ssl-when-making-a-psql-connection.md)
|
||||
- [Generate A UUID](postgres/generate-a-uuid.md)
|
||||
- [Generate Modern Primary Key Columns](postgres/generate-modern-primary-key-columns.md)
|
||||
- [Generate Random Alphanumeric Identifier](postgres/generate-random-alphanumeric-identifier.md)
|
||||
- [Generate Random UUIDs Without An Extension](postgres/generate-random-uuids-without-an-extension.md)
|
||||
- [Generate Series Of Numbers](postgres/generate-series-of-numbers.md)
|
||||
- [Generating UUIDs With pgcrypto](postgres/generating-uuids-with-pgcrypto.md)
|
||||
|
||||
46
postgres/generate-random-alphanumeric-identifier.md
Normal file
46
postgres/generate-random-alphanumeric-identifier.md
Normal file
@@ -0,0 +1,46 @@
|
||||
# Generate Random Alphanumeric Identifier
|
||||
|
||||
Here is a PostgreSQL query that uses
|
||||
[`pgcrypto`](https://www.postgresql.org/docs/current/pgcrypto.html) (for
|
||||
[`get_random_bytes`](https://www.postgresql.org/docs/current/pgcrypto.html#PGCRYPTO-RANDOM-DATA-FUNCS))
|
||||
and a CTE to generate a cryptographically-random 8-character alphanumeric
|
||||
identifier.
|
||||
|
||||
```sql
|
||||
-- First ensure pgcrypto is installed
|
||||
create extension if not exists pgcrypto;
|
||||
|
||||
-- Generates a single 8-character identifier
|
||||
with chars as (
|
||||
-- excludes some look-alike characters
|
||||
select '23456789ABCDEFGHJKLMNPQRSTUVWXYZabcdefghijkmnpqrstuvwxyz' as charset
|
||||
),
|
||||
random_bytes as (
|
||||
select gen_random_bytes(8) as bytes
|
||||
),
|
||||
positions as (
|
||||
select generate_series(0, 7) as pos
|
||||
)
|
||||
select string_agg(
|
||||
substr(
|
||||
charset,
|
||||
(get_byte(bytes, pos) % length(charset)) + 1,
|
||||
1
|
||||
),
|
||||
'' order by pos
|
||||
) as short_id
|
||||
from positions, random_bytes, chars;
|
||||
```
|
||||
|
||||
The
|
||||
[`generate_series`](https://www.postgresql.org/docs/current/functions-srf.html)
|
||||
gives us an 8-row table from 0 to 7 that we can use as indexes into the byte
|
||||
positions of the value we get from `gen_random_bytes`. Those random bytes get
|
||||
mapped to individual alphanumeric characters from `chars`. That then gets
|
||||
squeezed together with `string_agg`.
|
||||
|
||||
Note: the character set excludes some characters that can be mistaken for one
|
||||
another like `0` and `O` or `1` and `l`.
|
||||
|
||||
Note: you could change the right-bound of the `generate_series` to generate a
|
||||
different length identifier.
|
||||
Reference in New Issue
Block a user