Skip to content

Commit

Permalink
initial commit
Browse files Browse the repository at this point in the history
  • Loading branch information
recipe committed Feb 19, 2024
1 parent eeccc1a commit 157104d
Show file tree
Hide file tree
Showing 7 changed files with 1,135 additions and 479 deletions.
35 changes: 35 additions & 0 deletions .github/workflows/default.yml
Original file line number Diff line number Diff line change
@@ -0,0 +1,35 @@
name: mysql-semver test workflow

on: [push]

jobs:
tests:
runs-on: ubuntu-latest
name: tests

env:
DB_DATABASE: test_db
DB_USER: root
DB_PASSWORD: root
DB_HOST: localhost

steps:
- name: Set up MySQL server
run: |
sudo systemctl start mysql
mysql -uroot -proot -e "SELECT version();"
mysql -uroot -proot -e "CREATE DATABASE test_db DEFAULT CHARACTER SET utf8mb4;"
mysql -uroot -proot -e "SHOW DATABASES;"
- uses: actions/checkout@v3

- name: Set up stored functions
run: |
mysql -uroot -proot test_db < ./semver.sql
mysql -uroot -proot test_db < ./append_version.sql
- name: Test VERSION_COMPARE(version1, version2)
run: if mysql -uroot -proot test_db < ./tests/test_version_compare.sql | egrep '.'; then exit 1; fi

- name: Test GET_SORT_ORDER(version)
run: if mysql -uroot -proot test_db < ./tests/test_sort_order.sql | egrep -B100 'Test failed'; then exit 1; fi
6 changes: 6 additions & 0 deletions .gitignore
Original file line number Diff line number Diff line change
@@ -0,0 +1,6 @@
# IDE related
/.idea
/*.iml

# OS related
.DS_Store
1,128 changes: 649 additions & 479 deletions LICENSE

Large diffs are not rendered by default.

103 changes: 103 additions & 0 deletions append_version.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,103 @@
-- This file is part of Project recipe/mysql-semver, a program for working with Semantic Versions in MySQL.
-- Copyright (C) 2024 Vitaliy Demidov
--
-- This program is free software: you can redistribute it and/or modify
-- it under the terms of the GNU General Public License Version 3 as
-- published by the Free Software Foundation.
--
-- This program is distributed in the hope that it will be useful,
-- but WITHOUT ANY WARRANTY; without even the implied warranty of
-- MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
-- GNU General Public License for more details.
--
-- You should have received a copy of the GNU General Public License
-- along with this program. If not, see <https://www.gnu.org/licenses/>.

DELIMITER //

CREATE TABLE IF NOT EXISTS versions (
id INT UNSIGNED AUTO_INCREMENT PRIMARY KEY,
version VARCHAR(64) COLLATE utf8mb4_bin NOT NULL,
sort_order BIGINT UNSIGNED NOT NULL,
UNIQUE KEY unique_version (version),
KEY idx_sort_order_version (sort_order, version)
) ENGINE = InnoDB charset utf8mb4 //

DROP FUNCTION IF EXISTS `GET_SORT_ORDER` //

CREATE FUNCTION GET_SORT_ORDER(version VARCHAR(255)) RETURNS BIGINT UNSIGNED
NOT DETERMINISTIC
READS SQL DATA
SQL SECURITY INVOKER
BEGIN
DECLARE l BIGINT UNSIGNED DEFAULT 0;
DECLARE r BIGINT UNSIGNED DEFAULT ~0;
DECLARE records INT UNSIGNED;
DECLARE ver VARCHAR(255);
DECLARE sort_order BIGINT UNSIGNED;
DECLARE cmp TINYINT;
DECLARE hop INT UNSIGNED DEFAULT 0;

loop_1: REPEAT
# It has to be set to NULL because the next query may not update the value
# if there are no records in a range.
SET records = NULL;

SELECT t.version, t.sort_order, @sort_order_rows__
INTO ver, sort_order, records
FROM (
SELECT v.version, v.sort_order, @sort_order_rows__ := @sort_order_rows__ + 1 AS num
FROM versions v, (SELECT @sort_order_rows__ := 0) t
WHERE l < v.sort_order
AND v.sort_order < r
ORDER BY v.sort_order
) t
WHERE num IN ((@sort_order_rows__ + 1) / 2, (@sort_order_rows__ + 2) / 2);

IF records IS NULL THEN
LEAVE loop_1;
END IF;

SET cmp = VERSION_COMPARE(version, ver);

IF cmp < 0 THEN
SET r = sort_order;
ELSEIF cmp > 0 THEN
SET l = sort_order;
ELSE
RETURN sort_order;
END IF;

SET hop = hop + 1;

IF l = r OR hop = 1000 THEN
RETURN 0;
# SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = "Unexpected error";
END IF;
UNTIL records = 1 END REPEAT loop_1;

IF r - l < 2 THEN
# Full reordering must be done in this case to allocate free space.
RETURN 0;
END IF;

RETURN l + FLOOR((r - l) / 2);
END //

DROP TRIGGER IF EXISTS bi_versions_set_sort_order //

CREATE TRIGGER bi_versions_set_sort_order BEFORE INSERT ON versions
FOR EACH ROW
BEGIN
DECLARE v BIGINT UNSIGNED;

IF NEW.sort_order = 0 THEN
SELECT GET_SORT_ORDER(NEW.version) INTO v;
IF v = 0 THEN
SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = 'There is no space between consecutive versions. Table has to be fully reordered.';
END IF;
SET NEW.sort_order = v;
END IF;
END //

DELIMITER ;
241 changes: 241 additions & 0 deletions semver.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,241 @@

-- This file is part of Project recipe/mysql-semver, a program for working with Semantic Versions in MySQL.
-- Copyright (C) 2024 Vitaliy Demidov
--
-- This program is free software: you can redistribute it and/or modify
-- it under the terms of the GNU General Public License Version 3 as
-- published by the Free Software Foundation.
--
-- This program is distributed in the hope that it will be useful,
-- but WITHOUT ANY WARRANTY; without even the implied warranty of
-- MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
-- GNU General Public License for more details.
--
-- You should have received a copy of the GNU General Public License
-- along with this program. If not, see <https://www.gnu.org/licenses/>.

DELIMITER //

DROP FUNCTION IF EXISTS `SEMANTIC_VERSION` //

CREATE FUNCTION `SEMANTIC_VERSION`(version VARCHAR(255)) RETURNS VARCHAR(255)
DETERMINISTIC
NO SQL
SQL SECURITY INVOKER
BEGIN
DECLARE re VARCHAR(255) DEFAULT '^(0|[1-9]\\d*)\\.(0|[1-9]\\d*)\\.(0|[1-9]\\d*)(?:-((?:0|[1-9]\\d*|\\d*[a-zA-Z-][0-9a-zA-Z-]*)(?:\\.(?:0|[1-9]\\d*|\\d*[a-zA-Z-][0-9a-zA-Z-]*))*))?(?:\\+([0-9a-zA-Z-]+(?:\\.[0-9a-zA-Z-]+)*))?$';
DECLARE sem_ver VARCHAR(255) DEFAULT NULL;

IF version IS NULL THEN
RETURN NULL;
END IF;

SET sem_ver = REGEXP_REPLACE(version, re, '$1,$2,$3,$4,$5');

IF version = sem_ver THEN
SET sem_ver = NULL;
END IF;

RETURN sem_ver;
END //

DROP FUNCTION IF EXISTS `NAT_VERSION` //

CREATE FUNCTION `NAT_VERSION` (version VARCHAR(255)) RETURNS VARCHAR(255)
DETERMINISTIC
NO SQL
SQL SECURITY INVOKER
BEGIN
DECLARE re VARCHAR(255) DEFAULT '^(0|[1-9]\\d*)(?:\\.(0|[1-9]\\d*))?(?:\\.(0|[1-9]\\d*))?(?:[.-](.+))?$';
DECLARE ver VARCHAR(255) DEFAULT NULL;

IF version IS NULL THEN
RETURN NULL;
END IF;

SET ver = REGEXP_REPLACE(version, re, '$1,$2,$3,$4');

IF version = ver THEN
SET ver = CONCAT('0,0,0,', version, ',');
ELSE
SET ver = CONCAT(REPLACE(REPLACE(ver, ',,', ',0,'), ',,', ',0,'), ',');
END IF;

RETURN ver;
END //


DROP FUNCTION IF EXISTS `VERSION_COMPARE`//

CREATE FUNCTION `VERSION_COMPARE`(version1 VARCHAR(255), version2 VARCHAR(255)) RETURNS TINYINT
DETERMINISTIC
NO SQL
SQL SECURITY INVOKER
BEGIN
DECLARE re_digits_only VARCHAR(10) DEFAULT '^\\d+$';
DECLARE sem_version1 VARCHAR(255) DEFAULT IFNULL(SEMANTIC_VERSION(version1), NAT_VERSION(version1));
DECLARE sem_version2 VARCHAR(255) DEFAULT IFNULL(SEMANTIC_VERSION(version2), NAT_VERSION(version2));
DECLARE l VARCHAR(255);
DECLARE l_prev TINYINT UNSIGNED DEFAULT 0;
DECLARE l_next TINYINT UNSIGNED DEFAULT 0;
DECLARE lt_next TINYINT UNSIGNED DEFAULT 0;
DECLARE r VARCHAR(255);
DECLARE r_prev TINYINT UNSIGNED DEFAULT 0;
DECLARE r_next TINYINT UNSIGNED DEFAULT 0;
DECLARE rt_next TINYINT UNSIGNED DEFAULT 0;
DECLARE pos TINYINT UNSIGNED DEFAULT 0;
DECLARE res BIGINT;
DECLARE i TINYINT DEFAULT 0;
DECLARE l_pre_token VARCHAR(255);
DECLARE r_pre_token VARCHAR(255);

IF sem_version1 IS NULL OR sem_version2 IS NULL THEN
/* Version does not start with a digit */
IF version1 COLLATE utf8mb4_bin > version2 COLLATE utf8mb4_bin THEN
RETURN 1;
ELSEIF version1 COLLATE utf8mb4_bin < version2 COLLATE utf8mb4_bin THEN
RETURN -1;
ELSE
RETURN 0;
END IF;
END IF;

/* Compare major, minor, and patch versions */
do_main: LOOP
SET i = i + 1;
SET l_next = LOCATE(',', sem_version1, l_prev + 1);
SET r_next = LOCATE(',', sem_version2, r_prev + 1);
SET l = SUBSTR(sem_version1 FROM l_prev + 1 FOR l_next - l_prev - 1);
SET r = SUBSTR(sem_version2 FROM r_prev + 1 FOR r_next - r_prev - 1);
IF LENGTH(l) = LENGTH(r) THEN
/* To fix the INT max size error. */
IF LENGTH(l) > 9 THEN
SET pos = 1;
REPEAT
SET res = SUBSTR(l FROM pos FOR 9) - SUBSTR(r FROM pos FOR 9);
IF res != 0 THEN
RETURN IF(res < 0, -1, 1);
END IF;
SET pos = pos + 9;
UNTIL pos > LENGTH(l) END REPEAT;
ELSE
SET res = l - r;
IF res != 0 THEN
RETURN IF(res < 0, -1, 1);
END IF;
END IF;
ELSEIF LENGTH(l) < LENGTH(r) THEN
RETURN -1;
ELSE
RETURN 1;
END IF;
SET l_prev = l_next;
SET r_prev = r_next;
IF i = 3 THEN
LEAVE do_main;
END IF;
END LOOP do_main;

/* Compare pre-release versions */
SET i = 0;
SET l_next = LOCATE(',', sem_version1, l_prev + 1);
SET r_next = LOCATE(',', sem_version2, r_prev + 1);
SET l = IF(l_next - l_prev > 1, SUBSTR(sem_version1 FROM l_prev + 1 FOR l_next - l_prev - 1), '');
SET r = IF(r_next - r_prev > 1, SUBSTR(sem_version2 FROM r_prev + 1 FOR r_next - r_prev - 1), '');
do_outer: LOOP
IF l COLLATE utf8mb4_bin != r COLLATE utf8mb4_bin THEN
/* A pre-release version has lower precedence than a normal version: */
IF l = '' THEN
RETURN 1;
ELSEIF r = '' THEN
RETURN -1;
END IF;
SET l_prev = 0, r_prev = 0;
/* Normalize pre-release version by separating digits and letters with dots. */
/* Replace periods with dots, because 1.0.0-alpha.1 and 1.0.0-alpha-1 are the same. */
SET l = REGEXP_REPLACE(REGEXP_REPLACE(REGEXP_REPLACE(l, '[~-]', '.'), '([a-zA-Z])(\\d)', '$1.$2'), '([\\d])([a-zA-Z])', '$1.$2');
SET r = REGEXP_REPLACE(REGEXP_REPLACE(REGEXP_REPLACE(r, '[~-]', '.'), '([a-zA-Z])(\\d)', '$1.$2'), '([\\d])([a-zA-Z])', '$1.$2');
do_pre: LOOP
SET lt_next = LOCATE('.', l, l_prev + 1);
SET rt_next = LOCATE('.', r, r_prev + 1);
SET l_pre_token = IF(lt_next = 0, SUBSTR(l FROM l_prev + 1), SUBSTR(l FROM l_prev + 1 FOR lt_next - l_prev - 1));
SET r_pre_token = IF(rt_next = 0, SUBSTR(r FROM r_prev + 1), SUBSTR(r FROM r_prev + 1 FOR rt_next - r_prev - 1));

IF l_pre_token COLLATE utf8mb4_bin != r_pre_token COLLATE utf8mb4_bin THEN
/* A larger set of pre-release fields has a higher precedence than a smaller set,
if all of the preceding identifiers are equal. */
IF l_pre_token = '' THEN
RETURN -1;
ELSEIF r_pre_token = '' THEN
RETURN 1;
END IF;

IF REGEXP_LIKE(l_pre_token, re_digits_only) THEN
IF REGEXP_LIKE(r_pre_token, re_digits_only) THEN
/* Identifiers consisting of only digits are compared numerically. */
IF LENGTH(l_pre_token) = LENGTH(r_pre_token) THEN
/* To fix INT max size error */
IF LENGTH(l_pre_token) > 9 THEN
SET pos = 1;
REPEAT
SET res = SUBSTR(l_pre_token FROM pos FOR 9) - SUBSTR(r_pre_token FROM pos FOR 9);
IF res != 0 THEN
RETURN IF(res < 0, -1, 1);
END IF;
SET pos = pos + 9;
UNTIL pos > LENGTH(l_pre_token) END REPEAT;
ELSE
SET res = l_pre_token - r_pre_token;
IF res != 0 THEN
RETURN IF(res < 0, -1, 1);
END IF;
END IF;
ELSEIF LENGTH(l_pre_token) < LENGTH(r_pre_token) THEN
RETURN -1;
ELSE
RETURN 1;
END IF;
ELSE
/* Numeric identifiers always have lower precedence than non-numeric identifiers */
RETURN -1;
END IF;
ELSEIF REGEXP_LIKE(r_pre_token, re_digits_only) THEN
/* Numeric identifiers always have lower precedence than non-numeric identifiers */
RETURN 1;
ELSE
/* Identifiers with letters or hyphens are compared lexically in ASCII sort order. */
RETURN IF(l_pre_token COLLATE utf8mb4_bin < r_pre_token COLLATE utf8mb4_bin, -1, 1);
END IF;
END IF;

IF lt_next = 0 AND rt_next = 0 THEN
LEAVE do_pre;
ELSEIF lt_next = 0 THEN
/* A larger set of pre-release fields has a higher precedence than a smaller set */
RETURN -1;
ELSEIF rt_next = 0 THEN
/* A larger set of pre-release fields has a higher precedence than a smaller set */
RETURN 1;
ELSE
SET l_prev = lt_next;
SET r_prev = rt_next;
END IF;
END LOOP do_pre;
END IF;

/* According to the SemVer-2.0.0 the build metadata MUST be ignored when determining version precedence.
However we compare builds in the same way as pre-releases */
SET i = i + 1;
IF i = 2 THEN
LEAVE do_outer;
END IF;

SET l = SUBSTR(sem_version1 FROM l_next + 1 FOR LENGTH(sem_version1) - l_next);
SET r = SUBSTR(sem_version2 FROM r_next + 1 FOR LENGTH(sem_version2) - r_next);
END LOOP do_outer;

/* Versions are identical */
RETURN 0;
END //

DELIMITER ;
Loading

0 comments on commit 157104d

Please sign in to comment.