From 89f4826c56e61f519cfc8b195bfe5928f897a5ba Mon Sep 17 00:00:00 2001 From: Timm Fitschen <t.fitschen@indiscale.com> Date: Sun, 15 Mar 2020 20:47:51 +0100 Subject: [PATCH] WIP: integrate versioning into CUD procedures --- patches/patch20200312-2.1.2/patch.sh | 25 +--------- procedures/deleteEntity.sql | 1 - procedures/entityVersioning.sql | 52 ++++++++++++++++++++ procedures/insertEntity.sql | 6 +++ procedures/updateEntity.sql | 41 ++++++++++++---- tests/test_0_next_patch.sql | 38 ++++++++++++++- tests/test_autotap.sql | 2 +- tests/test_entity_versioning.sql | 71 +++++++++++++++++++++++++++- 8 files changed, 198 insertions(+), 38 deletions(-) diff --git a/patches/patch20200312-2.1.2/patch.sh b/patches/patch20200312-2.1.2/patch.sh index 848bfcc..121b433 100755 --- a/patches/patch20200312-2.1.2/patch.sh +++ b/patches/patch20200312-2.1.2/patch.sh @@ -36,30 +36,7 @@ fi check_version $OLD_VERSION -ENTITY_VERSION_TABLE='CREATE TABLE entity_version ( - entity_id UNSIGNED INT NOT NULL, - hash VARBINARY(255) NOT NULL, - version VARBINARY(255) NOT NULL, - _iversion UNSIGNED INT NOT NULL, - _ipparent UNSIGNED INT NULL, - srid VARBINARY(255) NOT NULL, - FOREIGN KEY (`srid`) REFERENCES `transactions` (`srid`), - FOREIGN KEY (`entity`) REFERENCES `entities` (`id`), - UNIQUE (`entity_id`, `version`), - UNIQUE (`entity_id`, `_iversion`), -) ENGINE=InnoDB;' - -TRANSACTIONS_TABLE='CREATE TABLE transactions ( - srid VARBINARY(255) NOT NULL PRIMARY KEY, - seconds UNSIGNED BIGINT NOT NULL, - nanos UNSIGNED INT(10) NOT NULL, - username VARBINARY(255) NOT NULL, - realm VARBINARY(255) NOT NULL -) ENGINE=InnoDB;' - - -mysql_execute "$TRANSACTIONS_TABLE"; -mysql_execute "$ENTITY_VERSION_TABLE"; +# TODO update_version $NEW_VERSION diff --git a/procedures/deleteEntity.sql b/procedures/deleteEntity.sql index 0a70f20..fe99897 100644 --- a/procedures/deleteEntity.sql +++ b/procedures/deleteEntity.sql @@ -41,7 +41,6 @@ delimiter // CREATE PROCEDURE db_2_0.deleteEntity(in EntityID INT UNSIGNED) BEGIN - DELETE FROM files where file_id=EntityID; DELETE FROM data_type WHERE domain_id=0 and (entity_id=0 and property_id=EntityID) or entity_id=EntityID; DELETE FROM collection_type WHERE domain_id=0 and (entity_id=0 and property_id=EntityID) or entity_id=EntityID; diff --git a/procedures/entityVersioning.sql b/procedures/entityVersioning.sql index a8183b2..38878a1 100644 --- a/procedures/entityVersioning.sql +++ b/procedures/entityVersioning.sql @@ -68,6 +68,58 @@ BEGIN END; // +DROP FUNCTION IF EXISTS db_2_0.get_primary_parent_version // +CREATE FUNCTION db_2_0.get_primary_parent_version(d INT UNSIGNED, v VARBINARY(255)) +RETURNS VARBINARY(255) +READS SQL DATA +BEGIN + RETURN ( + SELECT p.version + FROM entity_version AS e + INNER JOIN entity_version as p + ON (e._ipparent = p._iversion + AND e.entity_id = p.entity_id) + WHERE e.entity_id = d + AND e.version = v + LIMIT 1 + ); + +END; +// + + +DROP FUNCTION IF EXISTS db_2_0.get_version_timestamp // +CREATE FUNCTION db_2_0.get_version_timestamp( + EntityID INT UNSIGNED, + Version VARBINARY(255)) +RETURNS VARCHAR(255) +READS SQL DATA +BEGIN + RETURN ( + SELECT concat(t.seconds, '.', t.nanos) + FROM entity_version AS e + INNER JOIN transactions AS t + ON ( e.srid = t.srid ) + WHERE e.entity_id = EntityID + AND e.entity_version = Version; + ); +END; +// +DROP FUNCTION IF EXISTS db_2_0.get_head_version // +CREATE FUNCTION db_2_0.get_head_version( + EntityID INT UNSIGNED) +RETURNS VARBINARY(255) +READS SQL DATA +BEGIN + RETURN ( + SELECT e.version + FROM entity_version AS e + WHERE e.entity_id = EntityID + ORDER BY e._iversion DESC + LIMIT 1 + ); +END; +// delimiter ; diff --git a/procedures/insertEntity.sql b/procedures/insertEntity.sql index 8e307a8..94dba08 100644 --- a/procedures/insertEntity.sql +++ b/procedures/insertEntity.sql @@ -44,12 +44,18 @@ CREATE PROCEDURE db_2_0.insertEntity(in EntityName VARCHAR(255), in EntityDesc T BEGIN DECLARE NewEntityID INT UNSIGNED DEFAULT NULL; DECLARE NewACLID INT UNSIGNED DEFAULT NULL; + DECLARE Hash VARBINARY(255) DEFAULT SHA1(UUID()); + DECLARE Transaction VARBINARY(255) DEFAULT UUID(); call entityACL(NewACLID, ACL); INSERT INTO entities (name, description, role, acl) VALUES (EntityName, EntityDesc, EntityRole, NewACLID); SET NewEntityID = LAST_INSERT_ID(); + IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN + CALL insert_single_child_version(NewEntityID, Hash, Hash, Null, Transaction); + END IF; + Select NewEntityID as EntityID; END; diff --git a/procedures/updateEntity.sql b/procedures/updateEntity.sql index 7fa903a..4a9c6b9 100644 --- a/procedures/updateEntity.sql +++ b/procedures/updateEntity.sql @@ -31,21 +31,44 @@ DROP PROCEDURE IF EXISTS db_2_0.updateEntity; delimiter // -CREATE PROCEDURE db_2_0.updateEntity(in EntityID INT UNSIGNED, in EntityName VARCHAR(255), in EntityDescription TEXT, in EntityRole VARCHAR(255), in Datatype VARCHAR(255), in Collection VARCHAR(255), in ACL VARBINARY(65525)) -BEGIN - DECLARE ACLID INT UNSIGNED DEFAULT NULL; - call entityACL(ACLID, ACL); +CREATE PROCEDURE db_2_0.updateEntity( + in EntityID INT UNSIGNED, + in EntityName VARCHAR(255), + in EntityDescription TEXT, + in EntityRole VARCHAR(255), + in Datatype VARCHAR(255), + in Collection VARCHAR(255), + in ACL VARBINARY(65525)) +BEGIN + DECLARE ACLID INT UNSIGNED DEFAULT NULL; + DECLARE Hash VARBINARY(255) DEFAULT SHA1(UUID()); + DECLARE ParentVersion VARBINARY(255) DEFAULT NULL; + DECLARE Transaction VARBINARY(255) DEFAULT UUID(); - UPDATE entities e SET e.name = EntityName, e.description = EntityDescription, e.role=EntityRole, e.acl = ACLID where e.id = EntityID; + call entityACL(ACLID, ACL); - DELETE from data_type where domain_id=0 AND entity_id=0 AND property_id=EntityID; + IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN + SELECT e.version INTO ParentVersion + FROM entity_version as e + WHERE e.entity_id = EntityID + ORDER BY e._iversion DESC + LIMIT 1; + CALL insert_single_child_version( + EntityID, Hash, + SHA1(concat(ParentVersion, Hash)), + ParentVersion, Transaction); + END IF; + + UPDATE entities e SET e.name = EntityName, e.description = EntityDescription, e.role=EntityRole, e.acl = ACLID where e.id = EntityID; + + DELETE from data_type where domain_id=0 AND entity_id=0 AND property_id=EntityID; DELETE from collection_type where domain_id=0 AND entity_id=0 AND property_id=EntityID; IF Datatype IS NOT NULL THEN INSERT INTO data_type (domain_id, entity_id, property_id, datatype) SELECT 0, 0, EntityID, ( SELECT id from entities where name = Datatype LIMIT 1); - IF Collection IS NOT NULL THEN - INSERT INTO collection_type (domain_id, entity_id, property_id, collection) SELECT 0, 0, EntityID, Collection; - END IF; + IF Collection IS NOT NULL THEN + INSERT INTO collection_type (domain_id, entity_id, property_id, collection) SELECT 0, 0, EntityID, Collection; + END IF; END IF; END; diff --git a/tests/test_0_next_patch.sql b/tests/test_0_next_patch.sql index 7dae252..3d2e206 100644 --- a/tests/test_0_next_patch.sql +++ b/tests/test_0_next_patch.sql @@ -2,6 +2,18 @@ USE _caosdb_schema_unit_tests; DROP TABLE IF EXISTS entity_version; +DROP TABLE IF EXISTS transactions; + +CREATE TABLE transactions ( + srid VARBINARY(255) PRIMARY KEY, + seconds BIGINT UNSIGNED NOT NULL, + nanos INT(10) UNSIGNED NOT NULL, + username VARBINARY(255) NOT NULL, + realm VARBINARY(255) NOT NULL +) ENGINE=InnoDB; + +-- TODO remove ON DELETE CASCADE when feature is stable. +-- TODO ADD srid FOREIGN KEY and transactions table. CREATE TABLE entity_version ( entity_id INT UNSIGNED NOT NULL, hash VARBINARY(255) NOT NULL, @@ -9,7 +21,31 @@ CREATE TABLE entity_version ( _iversion INT UNSIGNED NOT NULL, _ipparent INT UNSIGNED NULL, srid VARBINARY(255) NOT NULL, - FOREIGN KEY (`entity_id`) REFERENCES `entities` (`id`), + FOREIGN KEY (`entity_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + -- FOREIGN KEY (`srid`) REFERENCES `transactions` (`srid`), UNIQUE (`entity_id`, `version`), UNIQUE (`entity_id`, `_iversion`) ) ENGINE=InnoDB; + + +DROP TABLE IF EXISTS feature_config; +CREATE TABLE feature_config ( + _key VARCHAR(255) PRIMARY KEY, + _value VARCHAR(255) +) ENGINE=InnoDB; + +delimiter // + +DROP FUNCTION IF EXISTS is_feature_config // +CREATE FUNCTION is_feature_config( + _Key VARCHAR(255), + Expected VARCHAR(255)) +RETURNS BOOLEAN +READS SQL DATA +BEGIN + RETURN ( + SELECT f._value = Expected FROM feature_config as f WHERE f._key = _Key + ); +END // + +delimiter ; diff --git a/tests/test_autotap.sql b/tests/test_autotap.sql index 347ee00..e7bc6f6 100644 --- a/tests/test_autotap.sql +++ b/tests/test_autotap.sql @@ -2289,7 +2289,7 @@ SELECT tap.constraint_type_is('_caosdb_schema_unit_tests','entity_version','enti SELECT tap.has_constraint('_caosdb_schema_unit_tests','entity_version','entity_version_ibfk_1',''); SELECT tap.constraint_type_is('_caosdb_schema_unit_tests','entity_version','entity_version_ibfk_1','FOREIGN KEY',''); -SELECT tap.fk_on_delete('_caosdb_schema_unit_tests','entity_version','entity_version_ibfk_1','RESTRICT',''); +SELECT tap.fk_on_delete('_caosdb_schema_unit_tests','entity_version','entity_version_ibfk_1','CASCADE',''); SELECT tap.fk_on_update('_caosdb_schema_unit_tests','entity_version','entity_version_ibfk_1','RESTRICT',''); -- *************************************************************** diff --git a/tests/test_entity_versioning.sql b/tests/test_entity_versioning.sql index dd2b0f8..c1c9a31 100644 --- a/tests/test_entity_versioning.sql +++ b/tests/test_entity_versioning.sql @@ -4,11 +4,20 @@ CALL tap.no_plan(); +-- ##################################################################### +-- TEST insert_single_child_version, get_primary_parent_version and +-- delete_all_entity_versions in isolation +-- ##################################################################### + -- SETUP DELETE FROM entities WHERE name="EntityName"; CALL entityACL(@ACLID1, "{acl1}"); CALL insertEntity("EntityName", "EntityDesc", "RECORDTYPE", "{acl1}"); SELECT id INTO @EntityID FROM entities WHERE name="EntityName"; +INSERT INTO transactions (srid,seconds,nanos,username,realm) VALUES +("SRIDbla", 1234, 2345, "me", "home"), +("SRIDblub", 2345, 3465, "me", "home"), +("SRIDblieb", 3456, 4576, "you", "home"); -- TEST insert_single_child_version @@ -30,12 +39,17 @@ SELECT tap.eq(@x, 0, "the original entity is the parent"); SELECT count(*) INTO @x FROM entity_version; SELECT tap.eq(@x, 2, "two version there yet"); -CALL _assert_throws(concat("CALL insert_single_child_version(", @EntityID, ', "hashblieb", "versionblieb", "non-existing-parent", "SRIDBlieb")'), "non existing parent throws"); +CALL tap._assert_throws(concat("CALL insert_single_child_version(", @EntityID, ', "hashblieb", "versionblieb", "non-existing-parent", "SRIDBlieb")'), "non existing parent throws"); SELECT count(*) INTO @x FROM entity_version; SELECT tap.eq(@x, 2, "still two version there"); +-- TEST get_primary_parent_version +SELECT tap.eq(get_primary_parent_version(@EntityID, "versionblub"), "versionbla", "returns correct parent for versionblub"); +SELECT tap.eq(get_primary_parent_version(@EntityID, "versionbla"), NULL, "versionbla has no parent"); + + -- TEST delete_all_entity_versions SELECT count(*) INTO @x FROM entity_version; SELECT tap.ok(@x > 0, "several versions in the table"); @@ -45,9 +59,62 @@ SELECT count(*) INTO @x FROM entity_version; SELECT tap.eq(@x, 0, "no versions there any more"); --- TEARDOWN +-- TEARDOWN clean up a litte DELETE FROM entities WHERE name="EntityName"; +-- ##################################################################### +-- TEST the call of insert_single_child_version from within insertEntity +-- ##################################################################### + +-- SETUP switch on the feature +INSERT INTO feature_config (_key, _value) VALUES ("ENTITY_VERSIONING", "ENABLED"); +SELECT count(*) INTO @x FROM entity_version; +SELECT tap.eq(@x, 0, "before insertEntity, no versions there"); + +-- TEST insertEntity - should produce a version w/o parent + +CALL insertEntity("EntityName", "EntityDesc", "RECORDTYPE", "{acl1}"); +SELECT id INTO @EntityID FROM entities WHERE name="EntityName"; +SELECT count(*) INTO @x FROM entity_version WHERE entity_id = @EntityID; +SELECT tap.eq(@x, 1, "after insertEntity, a version is there."); +SELECT _iversion INTO @x FROM entity_version WHERE entity_id = @EntityID and _ipparent is NULL; +SELECT tap.eq(@x, 0, "after insertEntity, the _iversion number is 0."); + +SELECT _ipparent INTO @x from entity_version WHERE entity_id = @EntityID; +SELECT tap.eq(@x, NULL, "no parent for the freshly inserted entity"); + + +-- TEST updateEntity - should produce a version with a parent +CALL updateEntity(@EntityID, "NewEntityName", "NewEntityDesc", "RECORD", NULL, NULL, "{acl1}"); +SELECT count(*) INTO @x FROM entity_version WHERE entity_id = @EntityID; +SELECT tap.eq(@x, 2, "after updateEntity, a second version is there."); + +SELECT _iversion INTO @x FROM entity_version WHERE entity_id = @EntityID and _ipparent = 0; +SELECT tap.eq(@x, 1, "after updateEntity, the _iversion number incremented."); +SELECT _ipparent INTO @x FROM entity_version WHERE entity_id = @EntityID and _ipparent = 0; +SELECT tap.eq(@x, 0, "after updateEntity, the _pparent points to the first version"); + +-- a 2nd updateEntity +CALL updateEntity(@EntityID, "EntityName", "EntityDesc", "RECORDTYPE", NULL, NULL, "{acl1}"); +SELECT count(*) INTO @x FROM entity_version WHERE entity_id = @EntityID; +SELECT tap.eq(@x, 3, "after 2nd updateEntity, a 3rd version is there."); + +SELECT _iversion INTO @x FROM entity_version WHERE entity_id = @EntityID and _ipparent = 1; +SELECT tap.eq(@x, 2, "after 2nd updateEntity, the _iversion number incremented again."); +SELECT _ipparent INTO @x FROM entity_version WHERE entity_id = @EntityID and _ipparent = 1; +SELECT tap.eq(@x, 1, "after 2nd updateEntity, the _pparent points to the 2nd version"); + +-- TEST deleteEntity - should remove all versions +CALL deleteEntity(@EntityID); +SELECT count(*) INTO @x FROM entity_version; +SELECT tap.eq(@x, 0, "no versions there any more"); + + +-- TEARDOWN + +DELETE FROM feature_config WHERE _key = "ENTITY_VERSIONING"; + + CALL tap.finish(); ROLLBACK; -- GitLab