|
| 1 | +--- |
| 2 | +layout: default |
| 3 | +title: ASCII IDs |
| 4 | +nav_order: 4 |
| 5 | +parent: String Manipulation |
| 6 | +permalink: /strings/ascii-id |
| 7 | +--- |
| 8 | + |
| 9 | +The following query generates random eight-character-long ASCII IDs (*id_counts*.*id_counter* pieces) using the specified alphabet (*char_templates*). The dash and underscore characters extend the alphanumeric alphabet to 64 characters allowing the selection of the six least significant bits from a random 64-bit number via bitwise AND (instead of *mod*). The *ids* block generates a 64-bit integer representation of the same ID. Saving character code before grouping in *ascii_ids* would not work because the query optimizer tends to rerun the query, executing the *random* function and generating the character and character code independently. The intermediate table aggregation operation prevents this optimization. |
| 10 | + |
| 11 | +~~~sql |
| 12 | +WITH |
| 13 | + id_counts(id_counter) AS (VALUES (3)), |
| 14 | + json_templates AS (SELECT '[' || replace(hex(zeroblob(id_counter*8-1)), '00', '0,') || '0]' AS json_template FROM id_counts), |
| 15 | + char_templates(char_template) AS (VALUES ('-0123456789ABCDEFGHIJKLMNOPQRSTUVWXYZabcdefghijklmnopqrstuvwxyz_')), |
| 16 | + ascii_ids AS ( |
| 17 | + SELECT group_concat(substr(char_template, (random() & 63) + 1, 1), '') AS ascii_id, "key"/8 AS counter |
| 18 | + FROM char_templates, json_templates, json_each(json_templates.json_template) AS terms |
| 19 | + GROUP BY counter |
| 20 | + ), |
| 21 | + ids AS ( |
| 22 | + SELECT counter, ascii_id, |
| 23 | + (unicode(substr(ascii_id, 1, 1)) << 8*7) + |
| 24 | + (unicode(substr(ascii_id, 2, 1)) << 8*6) + |
| 25 | + (unicode(substr(ascii_id, 3, 1)) << 8*5) + |
| 26 | + (unicode(substr(ascii_id, 4, 1)) << 8*4) + |
| 27 | + (unicode(substr(ascii_id, 5, 1)) << 8*3) + |
| 28 | + (unicode(substr(ascii_id, 6, 1)) << 8*2) + |
| 29 | + (unicode(substr(ascii_id, 7, 1)) << 8*1) + |
| 30 | + (unicode(substr(ascii_id, 8, 1)) << 8*0) AS bin_id |
| 31 | + FROM ascii_ids |
| 32 | + ) |
| 33 | +SELECT * FROM ids; |
| 34 | +~~~ |
| 35 | + |
| 36 | +**Sample output** |
| 37 | + |
| 38 | +| counter | ascii_id | bin_id | |
| 39 | +|---------|----------|---------------------| |
| 40 | +| 0 | qszS_Wed | 8175012247544227167 | |
| 41 | +| 1 | HwrjLnvG | 5221768093833786951 | |
| 42 | +| 2 | bXHJexP0 | 7086493498034638896 | |
0 commit comments