Skip to content

Instantly share code, notes, and snippets.

@odan
Last active January 12, 2024 01:11
Show Gist options
  • Star 6 You must be signed in to star a gist
  • Fork 3 You must be signed in to fork a gist
  • Save odan/6a80147659e0d623d2b9bcc1086e5caa to your computer and use it in GitHub Desktop.
Save odan/6a80147659e0d623d2b9bcc1086e5caa to your computer and use it in GitHub Desktop.
Generating UUID v4 in MySQL

Generating UUID v4 in MySQL

SELECT
  LOWER(
    CONCAT(
      # 1th and 2nd block are made of 6 random bytes
      HEX(RANDOM_BYTES(4)),
      '-',
      HEX(RANDOM_BYTES(2)),
      # 3th block will start with a 4 indicating the version, remaining is random
      '-4',
      SUBSTR(HEX(RANDOM_BYTES(2)), 2, 3),
      '-',
      # 4th block first nibble can only be 8, 9 A or B, remaining is random
      CONCAT(
        HEX(FLOOR(ASCII(RANDOM_BYTES(1)) / 64) + 8),
        SUBSTR(HEX(RANDOM_BYTES(2)), 2, 3)
      ),
      '-',
      # 5th block is made of 6 random bytes
      HEX(RANDOM_BYTES(6))
    )
  ) AS UUID;
@TyIsI
Copy link

TyIsI commented Nov 29, 2023

As quick reference, here's the function implementation of the above:

CREATE FUNCTION `UUIDV4` () RETURNS VARCHAR(255) NOT DETERMINISTIC NO SQL SQL SECURITY INVOKER
RETURN LOWER(
    CONCAT(
        # 1th and 2nd block are made of 6 random bytes
        HEX(RANDOM_BYTES(4)),
        '-',
        HEX(RANDOM_BYTES(2)),
        # 3th block will start with a 4 indicating the version, remaining is random
        '-4',
        SUBSTR(HEX(RANDOM_BYTES(2)), 2, 3),
        '-',
        # 4th block first nibble can only be 8, 9 A or B, remaining is random
        CONCAT(
            HEX(FLOOR(ASCII(RANDOM_BYTES(1)) / 64) + 8),
            SUBSTR(HEX(RANDOM_BYTES(2)), 2, 3)
        ),
        '-',
        # 5th block is made of 6 random bytes
        HEX(RANDOM_BYTES(6))
    )
);

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment