diff --git a/procedures/deleteEntity.sql b/procedures/deleteEntity.sql index fe99897937439ad962967891779547ef0321dc95..f8d676c5750e84b43ffeec70bf95387660761116 100644 --- a/procedures/deleteEntity.sql +++ b/procedures/deleteEntity.sql @@ -41,11 +41,28 @@ 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; - DELETE FROM entities where id=EntityID; - DELETE FROM entity_acl WHERE NOT EXISTS (SELECT 1 FROM entities WHERE entities.acl = entity_acl.id LIMIT 1); + DELETE FROM files where file_id=EntityID; + + DELETE FROM data_type + WHERE ( domain_id = 0 + AND entity_id = 0 + AND property_id = EntityID ) + OR datatype = EntityID; + + DELETE FROM collection_type + WHERE domain_id = 0 + AND entity_id = 0 + AND property_id = EntityID; + + DELETE FROM entities WHERE id=EntityID; + + DELETE FROM entity_acl + WHERE NOT EXISTS ( + SELECT 1 FROM entities + WHERE entities.acl = entity_acl.id LIMIT 1) + AND NOT EXISTS ( + SELECT 1 FROM archive_entities + WHERE archive_entities.acl = entity_acl.id LIMIT 1); END; // diff --git a/procedures/deleteEntityProperties.sql b/procedures/deleteEntityProperties.sql index 64715fe3011df62d52aada68b9eb0fa8057418a0..34d429d93532b608448dbc49246ae8305c617614 100644 --- a/procedures/deleteEntityProperties.sql +++ b/procedures/deleteEntityProperties.sql @@ -26,35 +26,156 @@ delimiter // CREATE PROCEDURE db_2_0.deleteEntityProperties(in EntityID INT UNSIGNED) BEGIN + DECLARE IVersion INT UNSIGNED DEFAULT NULL; -CALL deleteIsa(EntityID); - -DELETE FROM reference_data -where (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; -DELETE FROM null_data -where (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; -DELETE FROM text_data -where (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; -DELETE FROM name_data -where (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; -DELETE FROM enum_data -where (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; -DELETE FROM integer_data -where (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; -DELETE FROM double_data -where (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; -DELETE FROM datetime_data -where (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; -DELETE FROM date_data -where (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; -DELETE FROM name_overrides -WHERE (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; -DELETE FROM desc_overrides -WHERE (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; -DELETE FROM data_type -WHERE (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID OR (domain_id=0 AND entity_id=0 AND property_id=EntityID); - -DELETE FROM query_template_def WHERE id=EntityID; + CALL deleteIsa(EntityID); + + IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN + SELECT max(e._iversion) INTO IVersion + FROM entity_version AS e + WHERE e.entity_id = EntityID; + + INSERT INTO archive_reference_data (domain_id, entity_id, + property_id, value, status, pidx, _iversion) + SELECT domain_id, entity_id, property_id, value, status, + pidx, IVersion AS _iversion + FROM reference_data + WHERE (domain_id = 0 AND entity_id = EntityID) + OR domain_id = EntityID; + + INSERT INTO archive_null_data (domain_id, entity_id, + property_id, status, pidx, _iversion) + SELECT domain_id, entity_id, property_id, status, + pidx, IVersion AS _iversion + FROM null_data + WHERE (domain_id = 0 AND entity_id = EntityID) + OR domain_id = EntityID; + + INSERT INTO archive_text_data (domain_id, entity_id, + property_id, value, status, pidx, _iversion) + SELECT domain_id, entity_id, property_id, value, status, + pidx, IVersion AS _iversion + FROM text_data + WHERE (domain_id = 0 AND entity_id = EntityID) + OR domain_id = EntityID; + + INSERT INTO archive_name_data (domain_id, entity_id, + property_id, value, status, pidx, _iversion) + SELECT domain_id, entity_id, property_id, value, status, + pidx, IVersion AS _iversion + FROM name_data + WHERE (domain_id = 0 AND entity_id = EntityID) + OR domain_id = EntityID; + + INSERT INTO archive_enum_data (domain_id, entity_id, + property_id, value, status, pidx, _iversion) + SELECT domain_id, entity_id, property_id, value, status, + pidx, IVersion AS _iversion + FROM enum_data + WHERE (domain_id = 0 AND entity_id = EntityID) + OR domain_id = EntityID; + + INSERT INTO archive_integer_data (domain_id, entity_id, + property_id, value, status, pidx, _iversion, unit_sig) + SELECT domain_id, entity_id, property_id, value, status, + pidx, IVersion AS _iversion, unit_sig + FROM integer_data + WHERE (domain_id = 0 AND entity_id = EntityID) + OR domain_id = EntityID; + + INSERT INTO archive_double_data (domain_id, entity_id, + property_id, value, status, pidx, _iversion, unit_sig) + SELECT domain_id, entity_id, property_id, value, status, + pidx, IVersion AS _iversion, unit_sig + FROM double_data + WHERE (domain_id = 0 AND entity_id = EntityID) + OR domain_id = EntityID; + + INSERT INTO archive_datetime_data (domain_id, entity_id, + property_id, value, value_ns, status, pidx, _iversion) + SELECT domain_id, entity_id, property_id, value, value_ns, + status, pidx, IVersion AS _iversion + FROM datetime_data + WHERE (domain_id = 0 AND entity_id = EntityID) + OR domain_id = EntityID; + + INSERT INTO archive_date_data (domain_id, entity_id, + property_id, value, status, pidx, _iversion) + SELECT domain_id, entity_id, property_id, value, status, + pidx, IVersion AS _iversion + FROM date_data + WHERE (domain_id = 0 AND entity_id = EntityID) + OR domain_id = EntityID; + + INSERT INTO archive_name_overrides (domain_id, entity_id, + property_id, name, _iversion) + SELECT domain_id, entity_id, property_id, name, + IVersion AS _iversion + FROM name_overrides + WHERE (domain_id = 0 AND entity_id = EntityID) + OR domain_id = EntityID; + + INSERT INTO archive_desc_overrides (domain_id, entity_id, + property_id, description, _iversion) + SELECT domain_id, entity_id, property_id, description, + IVersion AS _iversion + FROM desc_overrides + WHERE (domain_id = 0 AND entity_id = EntityID) + OR domain_id = EntityID; + + INSERT INTO archive_data_type (domain_id, entity_id, + property_id, datatype, _iversion) + SELECT domain_id, entity_id, property_id, datatype, + IVersion AS _iversion + FROM data_type + WHERE (domain_id = 0 AND entity_id = EntityID) + OR domain_id = EntityID; + + INSERT INTO archive_collection_type (domain_id, entity_id, + property_id, collection, _iversion) + SELECT domain_id, entity_id, property_id, collection, + IVersion AS _iversion + FROM collection_type + WHERE (domain_id = 0 AND entity_id = EntityID) + OR domain_id = EntityID; + + INSERT INTO archive_query_template_def (id, definition, _iversion) + SELECT id, definition, IVersion AS _iversion + FROM query_template_def + WHERE id = EntityID; + + END IF; + + DELETE FROM reference_data + where (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; + DELETE FROM null_data + where (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; + DELETE FROM text_data + where (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; + DELETE FROM name_data + where (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; + DELETE FROM enum_data + where (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; + DELETE FROM integer_data + where (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; + DELETE FROM double_data + where (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; + DELETE FROM datetime_data + where (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; + DELETE FROM date_data + where (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; + + DELETE FROM name_overrides + WHERE (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; + DELETE FROM desc_overrides + WHERE (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; + + DELETE FROM data_type + WHERE (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; + DELETE FROM collection_type + WHERE (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; + + DELETE FROM query_template_def WHERE id=EntityID; END; // diff --git a/procedures/deleteIsaCache.sql b/procedures/deleteIsaCache.sql index 6713d4a2ffa90f00b973e986ac0c4647f00a7a61..7ae0518e9f867c7f23d339365d928fd6d6c1044b 100644 --- a/procedures/deleteIsaCache.sql +++ b/procedures/deleteIsaCache.sql @@ -41,8 +41,25 @@ Child entity for which all parental relations should be deleted. */ CREATE PROCEDURE db_2_0.deleteIsa(IN EntityID INT UNSIGNED) BEGIN - - DELETE FROM isa_cache WHERE child=EntityID or rpath=EntityID or rpath LIKE concat('%>',EntityID) or rpath LIKE concat('%>', EntityID, '>%'); + DECLARE IVersion INT UNSIGNED DEFAULT NULL; + + IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN + -- move to archive_isa + SELECT max(_iversion) INTO IVersion + FROM entity_version + WHERE entity_id = EntityID; + INSERT INTO archive_isa (child, child_iversion, parent) + SELECT e.child, IVersion AS child_iversion, e.parent + FROM isa_cache AS e + WHERE e.child = EntityID + AND e.rpath = CAST(EntityID AS BINARY); + END IF; + + DELETE FROM isa_cache + WHERE child = EntityID + OR rpath = EntityID + OR rpath LIKE concat('%>', EntityID) + OR rpath LIKE concat('%>', EntityID, '>%'); END; // diff --git a/procedures/entityACL.sql b/procedures/entityACL.sql index a4a0c2d09a055ffe0bc776cc45f4f6967c8dd003..5f5822b583566f4c2222991a651eb02d3795904e 100644 --- a/procedures/entityACL.sql +++ b/procedures/entityACL.sql @@ -28,8 +28,8 @@ CREATE PROCEDURE db_2_0.entityACL(out ACLID INT UNSIGNED, in ACLSTR VARBINARY(65 BEGIN SELECT id INTO ACLID FROM entity_acl as t WHERE t.acl=ACLSTR LIMIT 1; IF ACLID IS NULL THEN - INSERT INTO entity_acl (acl) VALUES (ACLSTR); - SET ACLID = LAST_INSERT_ID(); + INSERT INTO entity_acl (acl) VALUES (ACLSTR); + SET ACLID = LAST_INSERT_ID(); END IF; END; // diff --git a/procedures/updateEntity.sql b/procedures/updateEntity.sql index 36f72d8433195add94a34680be43f26222180c99..d14425aa888a87b01a91039519934f0f19f6b6fe 100644 --- a/procedures/updateEntity.sql +++ b/procedures/updateEntity.sql @@ -45,31 +45,77 @@ BEGIN DECLARE Version VARBINARY(255) DEFAULT NULL; DECLARE ParentVersion VARBINARY(255) DEFAULT NULL; DECLARE Transaction VARBINARY(255) DEFAULT NULL; + DECLARE OldIVersion INT UNSIGNED DEFAULT NULL; call entityACL(ACLID, ACL); IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN + SELECT max(_iversion) INTO OldIVersion + FROM entity_version + WHERE entity_id = EntityID; + + + -- move old data to archive + INSERT INTO archive_entities (id, name, description, role, + acl, _iversion) + SELECT e.id, e.name, e.description, e.role, e.acl, OldIVersion + FROM entities AS e + WHERE e.id = EntityID; + + INSERT INTO archive_data_type (domain_id, entity_id, property_id, + datatype, _iversion) + SELECT e.domain_id, e.entity_id, e.property_id, e.datatype, + OldIVersion + FROM data_type AS e + WHERE e.domain_id = 0 + AND e.entity_id = 0 + AND e.property_id = EntityID; + + INSERT INTO archive_collection_type (domain_id, entity_id, property_id, + collection, _iversion) + SELECT e.domain_id, e.entity_id, e.property_id, e.collection, + OldIVersion + FROM collection_type as e + WHERE e.domain_id = 0 + AND e.entity_id = 0 + AND e.property_id = EntityID; + + + + 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; + AND e._iversion = OldIVersion; SET Version = SHA1(concat(ParentVersion, Hash)); CALL insert_single_child_version( EntityID, Hash, Version, ParentVersion, Transaction); END IF; - UPDATE entities e SET e.name = EntityName, e.description = EntityDescription, e.role=EntityRole, e.acl = ACLID where e.id = EntityID; + 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; + 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); + 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; + INSERT INTO collection_type (domain_id, entity_id, property_id, + collection) + SELECT 0, 0, EntityID, Collection; END IF; END IF; diff --git a/tests/test_0_next_patch.sql b/tests/test_0_next_patch.sql index e3d174c6b5c24490ef9fc3543e4ce72cf35cc4ba..d2cbdaeef9271b35a07ddfdba51a16ced749d364 100644 --- a/tests/test_0_next_patch.sql +++ b/tests/test_0_next_patch.sql @@ -1,6 +1,23 @@ -USE _caosdb_schema_unit_tests; +--USE _caosdb_schema_unit_tests; +DROP TABLE IF EXISTS archive_reference_data; +DROP TABLE IF EXISTS archive_null_data; +DROP TABLE IF EXISTS archive_text_data; +DROP TABLE IF EXISTS archive_name_data; +DROP TABLE IF EXISTS archive_enum_data; +DROP TABLE IF EXISTS archive_integer_data; +DROP TABLE IF EXISTS archive_double_data; +DROP TABLE IF EXISTS archive_datetime_data; +DROP TABLE IF EXISTS archive_date_data; +DROP TABLE IF EXISTS archive_name_overrides; +DROP TABLE IF EXISTS archive_desc_overrides; +DROP TABLE IF EXISTS archive_data_type; +DROP TABLE IF EXISTS archive_collection_type; +DROP TABLE IF EXISTS archive_query_template_def; +DROP TABLE IF EXISTS archive_files; +DROP TABLE IF EXISTS archive_entities; +DROP TABLE IF EXISTS archive_isa; DROP TABLE IF EXISTS entity_version; DROP TABLE IF EXISTS transactions; @@ -20,10 +37,257 @@ CREATE TABLE entity_version ( _iversion INT UNSIGNED NOT NULL, _ipparent INT UNSIGNED NULL, srid VARBINARY(255) NOT NULL, + PRIMARY KEY (`entity_id`, `_iversion`), FOREIGN KEY (`entity_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, FOREIGN KEY (`srid`) REFERENCES `transactions` (`srid`), - UNIQUE (`entity_id`, `version`), - UNIQUE (`entity_id`, `_iversion`) + UNIQUE (`entity_id`, `version`) +) ENGINE=InnoDB; + +CREATE TABLE archive_isa ( + child INT UNSIGNED NOT NULL, + child_iversion INT UNSIGNED NOT NULL, + parent INT UNSIGNED NOT NULL, + FOREIGN KEY (`parent`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`child`, `child_iversion`) REFERENCES `entity_version` (`entity_id`, `_iversion`) ON DELETE CASCADE +) ENGINE=InnoDB; + +CREATE TABLE archive_reference_data ( + domain_id INT UNSIGNED NOT NULL, + entity_id INT UNSIGNED NOT NULL, + property_id INT UNSIGNED NOT NULL, + value INT UNSIGNED NOT NULL, + status ENUM('OBLIGATORY','RECOMMENDED','SUGGESTED','FIX','REPLACEMENT') + NOT NULL, + pidx INT(10) UNSIGNED NOT NULL, + _iversion INT UNSIGNED NOT NULL, + KEY (`domain_id`, `entity_id`, `_iversion`), + KEY (`domain_id`, `_iversion`), + FOREIGN KEY (`domain_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`entity_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`property_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`value`) REFERENCES `entities` (`id`) ON DELETE CASCADE +) ENGINE=InnoDB; + +CREATE TABLE archive_null_data ( + domain_id INT UNSIGNED NOT NULL, + entity_id INT UNSIGNED NOT NULL, + property_id INT UNSIGNED NOT NULL, + status ENUM('OBLIGATORY','RECOMMENDED','SUGGESTED','FIX') + NOT NULL, + pidx INT(10) UNSIGNED NOT NULL, + _iversion INT UNSIGNED NOT NULL, + KEY (`domain_id`, `entity_id`, `_iversion`), + KEY (`domain_id`, `_iversion`), + FOREIGN KEY (`domain_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`entity_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`property_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE +) ENGINE=InnoDB; + +CREATE TABLE archive_text_data ( + domain_id INT UNSIGNED NOT NULL, + entity_id INT UNSIGNED NOT NULL, + property_id INT UNSIGNED NOT NULL, + value TEXT NOT NULL, + status ENUM('OBLIGATORY','RECOMMENDED','SUGGESTED','FIX') + NOT NULL, + pidx INT(10) UNSIGNED NOT NULL, + _iversion INT UNSIGNED NOT NULL, + KEY (`domain_id`, `entity_id`, `_iversion`), + KEY (`domain_id`, `_iversion`), + FOREIGN KEY (`domain_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`entity_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`property_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE +) ENGINE=InnoDB; + +CREATE TABLE archive_name_data ( + domain_id INT UNSIGNED NOT NULL, + entity_id INT UNSIGNED NOT NULL, + property_id INT UNSIGNED NOT NULL, + value VARCHAR(255) NOT NULL, + status ENUM('OBLIGATORY','RECOMMENDED','SUGGESTED','FIX') + NOT NULL, + pidx INT(10) UNSIGNED NOT NULL, + _iversion INT UNSIGNED NOT NULL, + KEY (`domain_id`, `entity_id`, `_iversion`), + KEY (`domain_id`, `_iversion`), + KEY (`value`), + FOREIGN KEY (`domain_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`entity_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`property_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE +) ENGINE=InnoDB; + +CREATE TABLE archive_enum_data ( + domain_id INT UNSIGNED NOT NULL, + entity_id INT UNSIGNED NOT NULL, + property_id INT UNSIGNED NOT NULL, + value VARBINARY(255) NOT NULL, + status ENUM('OBLIGATORY','RECOMMENDED','SUGGESTED','FIX') + NOT NULL, + pidx INT(10) UNSIGNED NOT NULL, + _iversion INT UNSIGNED NOT NULL, + KEY (`domain_id`, `entity_id`, `_iversion`), + KEY (`domain_id`, `_iversion`), + FOREIGN KEY (`domain_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`entity_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`property_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE +) ENGINE=InnoDB; + +CREATE TABLE archive_integer_data ( + domain_id INT UNSIGNED NOT NULL, + entity_id INT UNSIGNED NOT NULL, + property_id INT UNSIGNED NOT NULL, + value BIGINT NOT NULL, + status ENUM('OBLIGATORY','RECOMMENDED','SUGGESTED','FIX') + NOT NULL, + pidx INT(10) UNSIGNED NOT NULL, + _iversion INT UNSIGNED NOT NULL, + unit_sig BIGINT DEFAULT NULL, + KEY (`domain_id`, `entity_id`, `_iversion`), + KEY (`domain_id`, `_iversion`), + FOREIGN KEY (`domain_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`entity_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`property_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE +) ENGINE=InnoDB; + +CREATE TABLE archive_double_data ( + domain_id INT UNSIGNED NOT NULL, + entity_id INT UNSIGNED NOT NULL, + property_id INT UNSIGNED NOT NULL, + value DOUBLE NOT NULL, + status ENUM('OBLIGATORY','RECOMMENDED','SUGGESTED','FIX') + NOT NULL, + pidx INT(10) UNSIGNED NOT NULL, + _iversion INT UNSIGNED NOT NULL, + unit_sig BIGINT DEFAULT NULL, + KEY (`domain_id`, `entity_id`, `_iversion`), + KEY (`domain_id`, `_iversion`), + FOREIGN KEY (`domain_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`entity_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`property_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE +) ENGINE=InnoDB; + +CREATE TABLE archive_datetime_data ( + domain_id INT UNSIGNED NOT NULL, + entity_id INT UNSIGNED NOT NULL, + property_id INT UNSIGNED NOT NULL, + value BIGINT NOT NULL, + value_ns INT(10) UNSIGNED DEFAULT NULL, + status ENUM('OBLIGATORY','RECOMMENDED','SUGGESTED','FIX') + NOT NULL, + pidx INT(10) UNSIGNED NOT NULL, + _iversion INT UNSIGNED NOT NULL, + KEY (`domain_id`, `entity_id`, `_iversion`), + KEY (`domain_id`, `_iversion`), + FOREIGN KEY (`domain_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`entity_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`property_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE +) ENGINE=InnoDB; + +CREATE TABLE archive_date_data ( + domain_id INT UNSIGNED NOT NULL, + entity_id INT UNSIGNED NOT NULL, + property_id INT UNSIGNED NOT NULL, + value INT(11) NOT NULL, + status ENUM('OBLIGATORY','RECOMMENDED','SUGGESTED','FIX') + NOT NULL, + pidx INT(10) UNSIGNED NOT NULL, + _iversion INT UNSIGNED NOT NULL, + KEY (`domain_id`, `entity_id`, `_iversion`), + KEY (`domain_id`, `_iversion`), + FOREIGN KEY (`domain_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`entity_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`property_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE +) ENGINE=InnoDB; + +CREATE TABLE archive_name_overrides ( + domain_id INT UNSIGNED NOT NULL, + entity_id INT UNSIGNED NOT NULL, + property_id INT UNSIGNED NOT NULL, + name VARCHAR(255) NOT NULL, + _iversion INT UNSIGNED NOT NULL, + UNIQUE KEY (`domain_id`, `entity_id`, `property_id`, `_iversion`), + KEY (`domain_id`, `entity_id`, `_iversion`), + KEY (`domain_id`, `_iversion`), + FOREIGN KEY (`domain_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`entity_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`property_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE +) ENGINE=InnoDB; + +CREATE TABLE archive_desc_overrides ( + domain_id INT UNSIGNED NOT NULL, + entity_id INT UNSIGNED NOT NULL, + property_id INT UNSIGNED NOT NULL, + description TEXT NOT NULL, + _iversion INT UNSIGNED NOT NULL, + UNIQUE KEY (`domain_id`, `entity_id`, `property_id`, `_iversion`), + KEY (`domain_id`, `entity_id`, `_iversion`), + KEY (`domain_id`, `_iversion`), + FOREIGN KEY (`domain_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`entity_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`property_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE +) ENGINE=InnoDB; + +CREATE TABLE archive_data_type ( + domain_id INT UNSIGNED NOT NULL, + entity_id INT UNSIGNED NOT NULL, + property_id INT UNSIGNED NOT NULL, + datatype INT UNSIGNED NOT NULL, + _iversion INT UNSIGNED NOT NULL, + UNIQUE KEY (`domain_id`, `entity_id`, `property_id`, `_iversion`), + KEY (`domain_id`, `entity_id`, `_iversion`), + KEY (`domain_id`, `_iversion`), + FOREIGN KEY (`domain_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`entity_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`property_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`datatype`) REFERENCES `entities` (`id`) ON DELETE CASCADE +) ENGINE=InnoDB; + +CREATE TABLE archive_collection_type ( + domain_id INT UNSIGNED NOT NULL, + entity_id INT UNSIGNED NOT NULL, + property_id INT UNSIGNED NOT NULL, + collection VARCHAR(255) NOT NULL, + _iversion INT UNSIGNED NOT NULL, + UNIQUE KEY (`domain_id`, `entity_id`, `property_id`, `_iversion`), + KEY (`domain_id`, `entity_id`, `_iversion`), + KEY (`domain_id`, `_iversion`), + FOREIGN KEY (`domain_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`entity_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE, + FOREIGN KEY (`property_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE +) ENGINE=InnoDB; + +CREATE TABLE archive_query_template_def ( + id INT UNSIGNED NOT NULL, + definition MEDIUMTEXT NOT NULL, + _iversion INT UNSIGNED NOT NULL, + PRIMARY KEY (`id`, `_iversion`), + FOREIGN KEY (`id`, `_iversion`) + REFERENCES `entity_version` (`entity_id`, `_iversion`) ON DELETE CASCADE +) ENGINE=InnoDB; + +CREATE TABLE archive_files ( + file_id INT UNSIGNED NOT NULL, + `path` TEXT NOT NULL, + size BIGINT UNSIGNED NOT NULL, + hash BINARY(64) DEFAULT NULL, + _iversion INT UNSIGNED NOT NULL, + PRIMARY KEY (`file_id`, `_iversion`), + FOREIGN KEY (`file_id`, `_iversion`) + REFERENCES `entity_version` (`entity_id`, `_iversion`) ON DELETE CASCADE +) ENGINE=InnoDB; + +CREATE TABLE archive_entities ( + id INT UNSIGNED NOT NULL, + name VARCHAR(255) DEFAULT NULL, + description TEXT DEFAULT NULL, + role ENUM('RECORDTYPE','RECORD','FILE','DOMAIN', + 'PROPERTY','DATATYPE','ROLE','QUERYTEMPLATE') NOT NULL, + acl INT(10) UNSIGNED DEFAULT NULL, + _iversion INT UNSIGNED NOT NULL, + PRIMARY KEY (`id`, `_iversion`), + FOREIGN KEY (`id`, `_iversion`) + REFERENCES `entity_version` (`entity_id`, `_iversion`) ON DELETE CASCADE, + FOREIGN KEY (`acl`) REFERENCES `entity_acl` (`id`) ) ENGINE=InnoDB; @@ -62,6 +326,36 @@ BEGIN END // +DROP PROCEDURE IF EXISTS setFileProperties // +CREATE PROCEDURE setFileProperties ( + in EntityID INT UNSIGNED, + in FilePath TEXT, + in FileSize BIGINT UNSIGNED, + in FileHash VARCHAR(255) +) +BEGIN + DECLARE IVersion INT UNSIGNED DEFAULT NULL; + + IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN + SELECT max(e._iversion) INTO IVersion + FROM entity_version AS e + WHERE e.entity_id = EntityID; + + INSERT INTO archive_files (file_id, path, size, hash, + _iversion) + SELECT file_id, path, size, hash, IVersion AS _iversion + FROM files + WHERE file_id = EntityID; + END IF; + + DELETE FROM files WHERE file_id = EntityID; + + IF FilePath IS NOT NULL THEN + INSERT INTO files (file_id, path, size, hash) + VALUES (EntityID, FilePath, FileSize, unhex(FileHash)); + END IF; + +END // diff --git a/tests/test_autotap.sql b/tests/test_autotap.sql index 670945015d7695e72afc4a71b9c3f3047c329d8a..b7f21cd62df68ef7757b78862854e8d571f2eaf1 100644 --- a/tests/test_autotap.sql +++ b/tests/test_autotap.sql @@ -2273,17 +2273,18 @@ 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`,`entity_version_ibfk_2`',''); +SELECT tap.constraints_are('_caosdb_schema_unit_tests','entity_version','`entity_id`,`PRIMARY`,`entity_version_ibfk_1`,`entity_version_ibfk_2`',''); -- CONSTRAINT entity_version.entity_id SELECT tap.has_constraint('_caosdb_schema_unit_tests','entity_version','entity_id',''); SELECT tap.constraint_type_is('_caosdb_schema_unit_tests','entity_version','entity_id','UNIQUE',''); --- CONSTRAINT entity_version.entity_id_2 +-- CONSTRAINT entity_version.PRIMARY -SELECT tap.has_constraint('_caosdb_schema_unit_tests','entity_version','entity_id_2',''); -SELECT tap.constraint_type_is('_caosdb_schema_unit_tests','entity_version','entity_id_2','UNIQUE',''); +SELECT tap.has_constraint('_caosdb_schema_unit_tests','entity_version','PRIMARY',''); +SELECT tap.constraint_type_is('_caosdb_schema_unit_tests','entity_version','PRIMARY','PRIMARY KEY',''); +SELECT tap.col_is_pk('_caosdb_schema_unit_tests','entity_version','`entity_id`,`_iversion`',''); -- CONSTRAINT entity_version.entity_version_ibfk_1 diff --git a/tests/test_entity_versioning.sql b/tests/test_entity_versioning.sql index 11e602107ba18ad72ee5ee181f3ce2130c37c2e5..dea994513ad274233467d21e636f0a22799ddc02 100644 --- a/tests/test_entity_versioning.sql +++ b/tests/test_entity_versioning.sql @@ -82,6 +82,8 @@ 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"); +SELECT tap.eq(count(*), 0, "no entity in archive_entities before first update") + FROM archive_entities; -- TEST updateEntity - should produce a version with a parent @@ -95,6 +97,9 @@ 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"); +SELECT tap.eq(count(*), 1, "after updateEntity, one entity in archive_entities") + FROM archive_entities; + -- and 2nd updateEntity SET @SRID = "SRIDblieb"; CALL updateEntity(@EntityID, "EntityName", "EntityDesc", "RECORDTYPE", NULL, NULL, "{acl1}");