diff --git a/patches/patch20200426-3.0.0/fix_unversioned.sql b/patches/patch20200426-3.0.0/fix_unversioned.sql new file mode 100644 index 0000000000000000000000000000000000000000..a44cfead58b804012256093374d6c20edaf44305 --- /dev/null +++ b/patches/patch20200426-3.0.0/fix_unversioned.sql @@ -0,0 +1,106 @@ +/* + * This file is a part of the CaosDB Project. + * + * Copyright (C) 2020 IndiScale GmbH <info@indiscale.com> + * Copyright (C) 2020 Timm Fitschen <t.fitschen@indiscale.com> + * + * This program is free software: you can redistribute it and/or modify + * it under the terms of the GNU Affero General Public License as + * published by the Free Software Foundation, either version 3 of the + * License, or (at your option) any later version. + * + * 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 Affero General Public License for more details. + * + * You should have received a copy of the GNU Affero General Public License + * along with this program. If not, see <https://www.gnu.org/licenses/>. + */ + +DROP PROCEDURE IF EXISTS _fix_unversioned; +delimiter // + +/* + * Generate entries in the entity_version table for all entities which are + * stored in the database and have no entry in the entity_version table yet. + */ +CREATE PROCEDURE _fix_unversioned() +BEGIN + DECLARE done INT DEFAULT FALSE; + DECLARE unversioned_id INT UNSIGNED; + -- cursor for unversioned entities + DECLARE entities_cur CURSOR FOR SELECT e.id + FROM entities AS e + WHERE NOT EXISTS ( + SELECT 1 FROM entity_version AS v WHERE v.entity_id = e.id); + DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; + + + OPEN entities_cur; + insert_loop: LOOP + FETCH entities_cur INTO unversioned_id; + IF done THEN + LEAVE insert_loop; + END IF; + + -- create an entry in transaction from the latest log in + -- transaction_log, hence the latest update of an entity + INSERT IGNORE INTO transactions (srid, username, realm, seconds, nanos) + SELECT tmp.srid, tmp.username, tmp.realm, tmp.seconds, tmp.nanos FROM ( + SELECT + SHA2(CONCAT(username, realm, seconds, nanos), 512) AS srid, + username AS username, + realm AS realm, + seconds AS seconds, + nanos AS nanos + FROM transaction_log + WHERE entity_id = unversioned_id + UNION SELECT + -- this is for the standard entities (id<100) + SHA2("", 512) AS srid, + "administration" As username, + "CaosDB" AS realm, + 0 as seconds, + 0 as nanos + ) AS tmp ORDER BY tmp.seconds DESC, tmp.nanos DESC LIMIT 1; + + -- insert single version into entity_version (for id>99) + INSERT INTO entity_version (entity_id, hash, version, _iversion, + _ipparent, srid) + SELECT + l.entity_id AS entity_id, + NULL as hash, + SHA1(UUID()) as version, + 1 AS _iversion, + NULL AS _ipparent, + t.srid AS srid + FROM transactions AS t JOIN transaction_log as l + ON ( t.seconds = l.seconds + AND t.nanos = l.nanos + AND t.username = l.username + AND t.realm = l.realm ) + WHERE l.entity_id = unversioned_id; + + -- insert single version into entity_version (for id<100) + INSERT IGNORE INTO entity_version (entity_id, hash, version, _iversion, + _ipparent, srid) + SELECT + unversioned_id AS entity_id, + "bla" AS hash, + SHA1(UUID()) AS version, + 1 AS _iversion, + NULL AS _ipparent, + t.srid AS srid + FROM transactions AS t + WHERE t.seconds = 0 AND t.nanos = 0; + + + END LOOP; + CLOSE entities_cur; +END; +// + +delimiter ; + +CALL _fix_unversioned(); diff --git a/patches/patch20200426-3.0.0/patch.sh b/patches/patch20200426-3.0.0/patch.sh index df536776786e92cab5086f03312e86fd9ae9b948..f05118bcce3f3418d88eea9a68a00825526d393c 100755 --- a/patches/patch20200426-3.0.0/patch.sh +++ b/patches/patch20200426-3.0.0/patch.sh @@ -38,6 +38,7 @@ check_version $OLD_VERSION mysql_execute_file $PATCH_DIR/feature_config.sql mysql_execute_file $PATCH_DIR/versioning.sql +mysql_execute_file $PATCH_DIR/fix_unversioned.sql update_version $NEW_VERSION diff --git a/procedures/entityVersioning.sql b/procedures/entityVersioning.sql index 5583d8626004568017a1e9ffc5c899501a9f315e..dc16f64d752f4736540e7e6bef97e2d6d78a6cad 100644 --- a/procedures/entityVersioning.sql +++ b/procedures/entityVersioning.sql @@ -1,5 +1,4 @@ /* - * ** header v3.0 * This file is a part of the CaosDB Project. * * Copyright (C) 2020 IndiScale GmbH <info@indiscale.com> @@ -17,8 +16,6 @@ * * You should have received a copy of the GNU Affero General Public License * along with this program. If not, see <https://www.gnu.org/licenses/>. - * - * ** end header */ @@ -215,4 +212,5 @@ END; // + delimiter ; diff --git a/tests/test_entity_versioning.sql b/tests/test_entity_versioning.sql index 3c7c96e7c76b05f62b86cbef68f4e9399747e62b..b84bc4063aa86c1292e511b550cccc6f9cadd58d 100644 --- a/tests/test_entity_versioning.sql +++ b/tests/test_entity_versioning.sql @@ -14,6 +14,8 @@ CALL tap.no_plan(); -- Disable versioning because we want to test `insert_single_child_version` -- separately from `insertEntity` but the former is called inside the latter -- when versioning is enabled. +DELETE FROM entity_version; +DELETE FROM transactions; DELETE FROM feature_config WHERE _key = "ENTITY_VERSIONING"; INSERT INTO transactions (srid,seconds,nanos,username,realm) VALUES ("SRIDbla", 1234, 2345, "me", "home"), @@ -167,8 +169,59 @@ SELECT tap.eq(@x, 0, "no versions there any more"); CALL deleteEntity(@ParentID); +CALL tap.finish(); +ROLLBACK; + +-- TEST _fix_unversioned +-- turn off version, insert entity, turn on version, call _fix_unversioned +-- The inserted entity should have no entry in entity_version at first and +-- after _fix_unversioned an entry is gerated. + +BEGIN; +CALL tap.no_plan(); + + +-- setup +DELETE FROM entity_version; +DELETE FROM transactions; +-- insert entity without versioning +DELETE FROM feature_config WHERE _key = "ENTITY_VERSIONING"; +DELETE FROM entities WHERE name="EntityName"; +CALL entityACL(@ACLID1, "{acl1}"); +CALL insertEntity("EntityName", "EntityDesc", "RECORDTYPE", "{acl1}"); +SELECT count(*) INTO @NumOfEntities FROM entities; +SELECT id INTO @EntityID FROM entities WHERE name="EntityName"; + +SET @TheUser = "TheUser"; -- used to identify the matching entry in transaction_log +-- fill transaction_log: one entity with two updates (and one insert) and another entity with insert and delete. +INSERT INTO transaction_log (transaction, entity_id, username, realm, seconds, nanos) + -- the first entry is the one which is be found by _fix_unversioned + VALUES ("Update", @EntityID, @TheUser, "CaosDB", 23458, 254), + -- the rest is dummy data + ("Update", @EntityID, "OtherUser", "CaosDB", 2345, 633), -- not the latest transaction + ("Insert", @EntityID, "OtherUser", "CaosDB", 245, 633), -- not the latest transaction + ("Insert", @EntityID + 1, @TheUser, "CaosDB", 2325, 653), -- not the right entity, inserted before our target + ("Delete", @EntityID + 1, @TheUser, "CaosDB", 232526, 653); -- not the right entity, deleted after our target + +SELECT tap.eq(COUNT(*), 5, "five entries in transaction_log") FROM transaction_log; +SELECT tap.eq(COUNT(*), 0, "no versioned entity there") FROM entity_version; +SELECT tap.eq(COUNT(*), 0, "no transaction there") FROM transactions; + +INSERT INTO feature_config (_key, _value) VALUES ("ENTITY_VERSIONING", "ENABLED"); +SELECT tap.eq(COUNT(*), 0, "still, no versioned entity there") FROM entity_version; +SELECT tap.eq(COUNT(*), 0, "still, no transaction there") FROM transactions; + +-- call _fix_unversioned +CALL _fix_unversioned(); +SELECT tap.eq(COUNT(*), @NumOfEntities, "after _fix_unversioned, one entry for our test entity in entity_version") FROM entity_version; +SELECT tap.eq(COUNT(*), 2, "after _fix_unversioned, one entry for our test entity in transactions, one for the standard entities.") FROM transactions; + +SELECT tap.eq(entity_id, @EntityID, "versioned entity has correct id") FROM entity_version WHERE entity_id > 99; +SELECT tap.ok(srid IS NOT NULL, "srid was generated and user/time matches entries from transaction_log") + FROM transactions AS t JOIN transaction_log AS l + ON (l.seconds = t.seconds AND l.nanos = t.nanos AND l.username = t.username AND l.realm = t.realm) + WHERE l.entity_id = @EntityID AND l.username = @TheUser; CALL tap.finish(); ROLLBACK; - diff --git a/tests/test_reference_values.sql b/tests/test_reference_values.sql index 1fae4fcf1adf4b837dbbbf660165588514da2d70..e59c1f1d21b651201b101b9563b3dc4aad610a97 100644 --- a/tests/test_reference_values.sql +++ b/tests/test_reference_values.sql @@ -9,6 +9,8 @@ CALL tap.no_plan(); -- SETUP +DELETE FROM entity_version; +DELETE FROM transactions; INSERT INTO transactions (srid,seconds,nanos,username,realm) VALUES ("SRIDbla", 1234, 2345, "me", "home"), ("SRIDblub", 2345, 3465, "me", "home"),