From b524231d0c59c6ec529355d28f6f9f8e2be0d081 Mon Sep 17 00:00:00 2001 From: Timm Fitschen <t.fitschen@indiscale.com> Date: Wed, 18 Mar 2020 23:11:26 +0100 Subject: [PATCH] WIP: versioning phase 2 --- procedures/entityVersioning.sql | 2 +- procedures/insertEntity.sql | 9 ++-- procedures/insertIsaCache.sql | 4 +- procedures/retrieveEntity.sql | 77 +++++++++++++++++++++++--------- procedures/updateEntity.sql | 10 +++-- tests/test_0_next_patch.sql | 28 +++++++++--- tests/test_autotap.sql | 10 ++++- tests/test_entity_versioning.sql | 12 ++++- 8 files changed, 113 insertions(+), 39 deletions(-) diff --git a/procedures/entityVersioning.sql b/procedures/entityVersioning.sql index 38878a1..ff5bd9e 100644 --- a/procedures/entityVersioning.sql +++ b/procedures/entityVersioning.sql @@ -101,7 +101,7 @@ BEGIN INNER JOIN transactions AS t ON ( e.srid = t.srid ) WHERE e.entity_id = EntityID - AND e.entity_version = Version; + AND e.version = Version ); END; // diff --git a/procedures/insertEntity.sql b/procedures/insertEntity.sql index 94dba08..72072aa 100644 --- a/procedures/insertEntity.sql +++ b/procedures/insertEntity.sql @@ -45,7 +45,8 @@ 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(); + DECLARE Version VARBINARY(255) DEFAULT NULL; + DECLARE Transaction VARBINARY(255) DEFAULT NULL; call entityACL(NewACLID, ACL); @@ -53,10 +54,12 @@ BEGIN SET NewEntityID = LAST_INSERT_ID(); IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN - CALL insert_single_child_version(NewEntityID, Hash, Hash, Null, Transaction); + SET Transaction = @SRID; + SET Version = Hash; + CALL insert_single_child_version(NewEntityID, Hash, Version, Null, Transaction); END IF; - Select NewEntityID as EntityID; + SELECT NewEntityID as EntityID, Version as Version; END; // diff --git a/procedures/insertIsaCache.sql b/procedures/insertIsaCache.sql index aacb4cd..dcea842 100644 --- a/procedures/insertIsaCache.sql +++ b/procedures/insertIsaCache.sql @@ -61,7 +61,7 @@ insert_is_a_proc: BEGIN concat(p, ">", i.rpath)) -- Else "p>super.rpath" AS rpath FROM isa_cache AS i WHERE i.child = p; -- Select rows with supertype - + -- Propagate to descendants: -- for each subtype of c: insert each supertype of p INSERT IGNORE INTO isa_cache SELECT @@ -79,7 +79,7 @@ insert_is_a_proc: BEGIN FROM isa_cache as l INNER JOIN isa_cache as r ON (l.parent = c AND c = r.child); -- Left: descendants of c, right: ancestors - + END; // diff --git a/procedures/retrieveEntity.sql b/procedures/retrieveEntity.sql index 1e2621b..e197177 100644 --- a/procedures/retrieveEntity.sql +++ b/procedures/retrieveEntity.sql @@ -29,29 +29,62 @@ drop procedure if exists db_2_0.retrieveEntity // create procedure db_2_0.retrieveEntity(in EntityID INT UNSIGNED) BEGIN - DECLARE FilePath VARCHAR(255) DEFAULT NULL; - DECLARE FileSize VARCHAR(255) DEFAULT NULL; - DECLARE FileHash VARCHAR(255) DEFAULT NULL; - DECLARE DatatypeID INT UNSIGNED DEFAULT NULL; + DECLARE FilePath VARCHAR(255) DEFAULT NULL; + DECLARE FileSize VARCHAR(255) DEFAULT NULL; + DECLARE FileHash VARCHAR(255) DEFAULT NULL; + DECLARE DatatypeID INT UNSIGNED DEFAULT NULL; DECLARE CollectionName VARCHAR(255) DEFAULT NULL; - - Select path, size, hex(hash) into FilePath, FileSize, FileHash from files where file_id = EntityID LIMIT 1; - Select datatype into DatatypeID from data_type where domain_id=0 and entity_id=0 and property_id=EntityID LIMIT 1; - - SELECT collection into CollectionName from collection_type where domain_id=0 and entity_id=0 and property_id=EntityID LIMIT 1; - - Select - (Select name from entities where id=DatatypeID) as Datatype, - CollectionName as Collection, - EntityID as EntityID, - e.name as EntityName, - e.description as EntityDesc, - e.role as EntityRole, - FileSize as FileSize, - FilePath as FilePath, - FileHash as FileHash, - (SELECT acl FROM entity_acl as a WHERE a.id = e.acl) as ACL - from entities e where id = EntityID LIMIT 1; + DECLARE Version VARBINARY(255) DEFAULT NULL; + DECLARE VersionSeconds BIGINT UNSIGNED DEFAULT NULL; + DECLARE VersionNanos INT(10) UNSIGNED DEFAULT NULL; + + + IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN + SET Version = get_head_version(EntityID); + SELECT t.seconds, t.nanos + INTO VersionSeconds, VersionNanos + FROM entity_version AS e + INNER JOIN transactions AS t + ON ( e.srid = t.srid ) + WHERE e.entity_id = EntityID + AND e.version = Version; + END IF; + + Select path, size, hex(hash) + into FilePath, FileSize, FileHash + from files + where file_id = EntityID + LIMIT 1; + + Select datatype into DatatypeID + from data_type + where domain_id=0 + and entity_id=0 + and property_id=EntityID + LIMIT 1; + + SELECT collection into CollectionName + from collection_type + where domain_id=0 + and entity_id=0 + and property_id=EntityID + LIMIT 1; + + Select + (Select name from entities where id=DatatypeID) as Datatype, + CollectionName as Collection, + EntityID as EntityID, + e.name as EntityName, + e.description as EntityDesc, + e.role as EntityRole, + FileSize as FileSize, + FilePath as FilePath, + FileHash as FileHash, + (SELECT acl FROM entity_acl as a WHERE a.id = e.acl) as ACL, + Version as Version, + VersionSeconds as VersionSeconds, + VersionNanos as VersionNanos + from entities e where id = EntityID LIMIT 1; END; // diff --git a/procedures/updateEntity.sql b/procedures/updateEntity.sql index 4a9c6b9..36f72d8 100644 --- a/procedures/updateEntity.sql +++ b/procedures/updateEntity.sql @@ -42,20 +42,22 @@ CREATE PROCEDURE db_2_0.updateEntity( BEGIN DECLARE ACLID INT UNSIGNED DEFAULT NULL; DECLARE Hash VARBINARY(255) DEFAULT SHA1(UUID()); + DECLARE Version VARBINARY(255) DEFAULT NULL; DECLARE ParentVersion VARBINARY(255) DEFAULT NULL; - DECLARE Transaction VARBINARY(255) DEFAULT UUID(); + DECLARE Transaction VARBINARY(255) DEFAULT NULL; call entityACL(ACLID, ACL); IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN + SET Transaction = @SRID; SELECT e.version INTO ParentVersion FROM entity_version as e WHERE e.entity_id = EntityID ORDER BY e._iversion DESC LIMIT 1; + SET Version = SHA1(concat(ParentVersion, Hash)); CALL insert_single_child_version( - EntityID, Hash, - SHA1(concat(ParentVersion, Hash)), + EntityID, Hash, Version, ParentVersion, Transaction); END IF; @@ -71,6 +73,8 @@ BEGIN END IF; END IF; + Select Version as Version; + END; // delimiter ; diff --git a/tests/test_0_next_patch.sql b/tests/test_0_next_patch.sql index 3d2e206..e3d174c 100644 --- a/tests/test_0_next_patch.sql +++ b/tests/test_0_next_patch.sql @@ -6,14 +6,13 @@ 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 + realm VARBINARY(255) NOT NULL, + seconds BIGINT UNSIGNED NOT NULL, + nanos INT(10) UNSIGNED 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, @@ -22,7 +21,7 @@ CREATE TABLE entity_version ( _ipparent INT UNSIGNED NULL, srid VARBINARY(255) NOT NULL, FOREIGN KEY (`entity_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, - -- FOREIGN KEY (`srid`) REFERENCES `transactions` (`srid`), + FOREIGN KEY (`srid`) REFERENCES `transactions` (`srid`), UNIQUE (`entity_id`, `version`), UNIQUE (`entity_id`, `_iversion`) ) ENGINE=InnoDB; @@ -48,4 +47,23 @@ BEGIN ); END // +DROP PROCEDURE IF EXISTS set_transaction // +CREATE PROCEDURE set_transaction( + srid VARBINARY(255), + username VARCHAR(255), + realm VARCHAR(255), + seconds BIGINT UNSIGNED, + nanos INT(10) UNSIGNED) +BEGIN + + SET @SRID = srid; + INSERT INTO transactions (srid, username, realm, seconds, nanos) + VALUES (srid, username, realm, seconds, nanos); +END // + + + + + + delimiter ; diff --git a/tests/test_autotap.sql b/tests/test_autotap.sql index e7bc6f6..6709450 100644 --- a/tests/test_autotap.sql +++ b/tests/test_autotap.sql @@ -2273,7 +2273,7 @@ SELECT tap.col_charset_is('_caosdb_schema_unit_tests','entity_version','srid',NU SELECT tap.col_collation_is('_caosdb_schema_unit_tests','entity_version','srid',NULL,''); -- CONSTRAINTS -SELECT tap.constraints_are('_caosdb_schema_unit_tests','entity_version','`entity_id`,`entity_id_2`,`entity_version_ibfk_1`',''); +SELECT tap.constraints_are('_caosdb_schema_unit_tests','entity_version','`entity_id`,`entity_id_2`,`entity_version_ibfk_1`,`entity_version_ibfk_2`',''); -- CONSTRAINT entity_version.entity_id @@ -2292,6 +2292,14 @@ SELECT tap.constraint_type_is('_caosdb_schema_unit_tests','entity_version','enti 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',''); +-- CONSTRAINT entity_version.entity_version_ibfk_2 + +SELECT tap.has_constraint('_caosdb_schema_unit_tests','entity_version','entity_version_ibfk_2',''); +SELECT tap.constraint_type_is('_caosdb_schema_unit_tests','entity_version','entity_version_ibfk_2','FOREIGN KEY',''); +SELECT tap.fk_on_delete('_caosdb_schema_unit_tests','entity_version','entity_version_ibfk_2','RESTRICT',''); +SELECT tap.fk_on_update('_caosdb_schema_unit_tests','entity_version','entity_version_ibfk_2','RESTRICT',''); + + -- *************************************************************** -- FUNCTIONS -- *************************************************************** diff --git a/tests/test_entity_versioning.sql b/tests/test_entity_versioning.sql index c1c9a31..11e6021 100644 --- a/tests/test_entity_versioning.sql +++ b/tests/test_entity_versioning.sql @@ -72,7 +72,7 @@ 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 - +SET @SRID = "SRIDbla"; 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; @@ -85,6 +85,7 @@ SELECT tap.eq(@x, NULL, "no parent for the freshly inserted entity"); -- TEST updateEntity - should produce a version with a parent +SET @SRID = "SRIDblub"; 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."); @@ -94,7 +95,8 @@ 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 +-- and 2nd updateEntity +SET @SRID = "SRIDblieb"; 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."); @@ -103,6 +105,12 @@ SELECT _iversion INTO @x FROM entity_version WHERE entity_id = @EntityID and _ip 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"); +SELECT tap.eq("SRIDblieb", srid, "correct transaction was stored") FROM entity_version WHERE entity_id = @EntityID AND _ipparent = 1; + + +-- TEST retrieveEntity + +CALL retrieveEntity(@EntityID); -- TEST deleteEntity - should remove all versions CALL deleteEntity(@EntityID); -- GitLab