diff --git a/CHANGELOG.md b/CHANGELOG.md new file mode 100644 index 0000000000000000000000000000000000000000..09e230a66befee51524856a62df9d3031c184e88 --- /dev/null +++ b/CHANGELOG.md @@ -0,0 +1,19 @@ +# Changelog +All notable changes to this project will be documented in this file. + +The format is based on [Keep a Changelog](https://keepachangelog.com/en/1.1.0/), +and this project adheres to [Semantic Versioning](https://semver.org/spec/v2.0.0.html). + + +## [Unreleased] + +### Added + +### Changed + +### Deprecated + +* Table `transaction_log` is deprecated. The functionality is being replaced by the `transactions` table. + +### Fixed + diff --git a/patches/patch20200312-2.1.2/patch.sh b/patches/patch20200312-2.1.2/patch.sh new file mode 100755 index 0000000000000000000000000000000000000000..848bfcc26a8a406149fd09bbc234970aaffe642c --- /dev/null +++ b/patches/patch20200312-2.1.2/patch.sh @@ -0,0 +1,68 @@ +#!/bin/bash +# +# ** header v3.0 +# This file is a part of the CaosDB Project. +# +# Copyright (C) 2018 Research Group Biomedical Physics, +# Max-Planck-Institute for Dynamics and Self-Organization Göttingen +# +# 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/>. +# +# ** end header +# +# new entity_version table +# Update mysql schema to version v2.1.2 +NEW_VERSION="v2.1.2" +OLD_VERSION="v2.1.2" + +if [ -z "$UTILSPATH" ]; then + UTILSPATH="../utils" +fi + +. $UTILSPATH/patch_header.sh $* + + +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"; + + +update_version $NEW_VERSION + +success + diff --git a/procedures/entityVersioning.sql b/procedures/entityVersioning.sql new file mode 100644 index 0000000000000000000000000000000000000000..a8183b2486041bdda790389afa78531c414aad58 --- /dev/null +++ b/procedures/entityVersioning.sql @@ -0,0 +1,73 @@ +/* + * ** header v3.0 + * 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/>. + * + * ** end header + */ + +DROP PROCEDURE IF EXISTS db_2_0.insert_single_child_version; +delimiter // + +CREATE PROCEDURE db_2_0.insert_single_child_version( + in EntityID INT UNSIGNED, + in Hash VARBINARY(255), + in Version VARBINARY(255), + in Parent VARBINARY(255), + in Transaction VARBINARY(255)) + +BEGIN + DECLARE newiversion INT UNSIGNED DEFAULT NULL; + DECLARE newipparent INT UNSIGNED DEFAULT NULL; + + -- find _ipparent + IF Parent IS NOT NULL THEN + SELECT e._iversion INTO newipparent FROM entity_version as e WHERE e.entity_id = EntityID AND e.version = Parent; + IF newipparent IS NULL THEN + -- throw error; + SELECT concat("This parent does not exists: ", Parent) from nonexisting; + END IF; + END IF; + + + -- generate _iversion + SELECT max(e._iversion)+1 INTO newiversion FROM entity_version as e WHERE e.entity_id=EntityID; + IF newiversion IS NULL THEN + SET newiversion = 0; + END IF; + + INSERT INTO entity_version (entity_id, hash, version, _iversion, _ipparent, srid) VALUES (EntityID, Hash, Version, newiversion, newipparent, Transaction); + + + +END; +// + +DROP PROCEDURE IF EXISTS db_2_0.delete_all_entity_versions // +CREATE PROCEDURE db_2_0.delete_all_entity_versions( + in EntityID INT UNSIGNED) +BEGIN + + DELETE FROM entity_version WHERE entity_id = EntityID; + +END; +// + + + +delimiter ; diff --git a/tests/test_0_next_patch.sql b/tests/test_0_next_patch.sql new file mode 100644 index 0000000000000000000000000000000000000000..7dae25234f699b21fc29dbb16742b31cf4a16222 --- /dev/null +++ b/tests/test_0_next_patch.sql @@ -0,0 +1,15 @@ + +USE _caosdb_schema_unit_tests; + +DROP TABLE IF EXISTS entity_version; +CREATE TABLE entity_version ( + entity_id INT UNSIGNED NOT NULL, + hash VARBINARY(255) NOT NULL, + version VARBINARY(255) NOT NULL, + _iversion INT UNSIGNED NOT NULL, + _ipparent INT UNSIGNED NULL, + srid VARBINARY(255) NOT NULL, + FOREIGN KEY (`entity_id`) REFERENCES `entities` (`id`), + UNIQUE (`entity_id`, `version`), + UNIQUE (`entity_id`, `_iversion`) +) ENGINE=InnoDB; diff --git a/tests/test_0_setup.sql b/tests/test_0_setup.sql new file mode 100644 index 0000000000000000000000000000000000000000..9b98f5dfac9625e590b4e15ffdc7560021760fd7 --- /dev/null +++ b/tests/test_0_setup.sql @@ -0,0 +1,24 @@ + +/** + * Execute an SQL statement and pass if the statement throws an SQLEXCEPTION. + * Otherwise, fail with the given msg. + */ +DROP PROCEDURE IF EXISTS tap._assert_throws; +delimiter // +CREATE PROCEDURE tap._assert_throws(in stmt TEXT, in msg TEXT) +BEGIN + DECLARE EXIT HANDLER FOR SQLEXCEPTION BEGIN + SELECT tap.pass(msg); + END; + SET @stmt = stmt; + PREPARE _stmt from @stmt; + EXECUTE _stmt; + + SELECT tap.fail(msg); +END // + +delimiter ; + + +-- test helper +-- CALL tap._assert_throws("SELECT * FROM non-existing", "should throw an error"); diff --git a/tests/test_autotap.sql b/tests/test_autotap.sql index f60bb3fca85cceda5956dac74e9fa9948b13a707..347ee00d9f712356adf95a7d26da8ff30086320e 100644 --- a/tests/test_autotap.sql +++ b/tests/test_autotap.sql @@ -33,8 +33,6 @@ SELECT tap.has_schema('_caosdb_schema_unit_tests',''); -- TABLES -- *************************************************************** -SELECT tap.tables_are('_caosdb_schema_unit_tests','`collection_type`,`data_type`,`date_data`,`datetime_data`,`desc_overrides`,`double_data`,`entities`,`entity_acl`,`enum_data`,`files`,`integer_data`,`isa_cache`,`logging`,`name_data`,`name_overrides`,`null_data`,`passwd`,`permissions`,`query_template_def`,`reference_data`,`roles`,`rules`,`stats`,`text_data`,`transaction_log`,`units_lin_con`,`user_info`,`user_roles`',''); - -- *************************************************************** -- TABLE _caosdb_schema_unit_tests.collection_type -- *************************************************************** @@ -2210,10 +2208,93 @@ SELECT tap.fk_on_delete('_caosdb_schema_unit_tests','user_roles','user_roles_ibf SELECT tap.fk_on_update('_caosdb_schema_unit_tests','user_roles','user_roles_ibfk_1','RESTRICT',''); -- *************************************************************** --- FUNCTIONS +-- TABLE _caosdb_schema_unit_tests.entity_version -- *************************************************************** -SELECT tap.routines_are('_caosdb_schema_unit_tests','FUNCTION','`CaosDBVersion`,`convert_unit`,`constructDateTimeWhereClauseForColumn`,`getAggValueWhereClause`,`getDateTimeWhereClause`,`getDoubleWhereClause`,`getDateWhereClause`,`makeStmt`,`standard_unit`',''); +SELECT tap.has_table('_caosdb_schema_unit_tests','entity_version',''); +SELECT tap.table_collation_is('_caosdb_schema_unit_tests','entity_version','utf8_unicode_ci',''); +SELECT tap.table_engine_is('_caosdb_schema_unit_tests','entity_version','InnoDB',''); + +-- COLUMNS +SELECT tap.columns_are('_caosdb_schema_unit_tests','entity_version','`entity_id`,`hash`,`version`,`_iversion`,`_ipparent`,`srid`',''); + +-- COLUMN entity_version.entity_id + +SELECT tap.has_column('_caosdb_schema_unit_tests','entity_version','entity_id',''); +SELECT tap.col_column_type_is('_caosdb_schema_unit_tests','entity_version','entity_id','int(10) unsigned',''); +SELECT tap.col_extra_is('_caosdb_schema_unit_tests','entity_version','entity_id','',''); +SELECT tap.col_default_is('_caosdb_schema_unit_tests','entity_version','entity_id',NULL,''); +SELECT tap.col_charset_is('_caosdb_schema_unit_tests','entity_version','entity_id',NULL,''); +SELECT tap.col_collation_is('_caosdb_schema_unit_tests','entity_version','entity_id',NULL,''); + +-- COLUMN entity_version.hash + +SELECT tap.has_column('_caosdb_schema_unit_tests','entity_version','hash',''); +SELECT tap.col_column_type_is('_caosdb_schema_unit_tests','entity_version','hash','varbinary(255)',''); +SELECT tap.col_extra_is('_caosdb_schema_unit_tests','entity_version','hash','',''); +SELECT tap.col_default_is('_caosdb_schema_unit_tests','entity_version','hash',NULL,''); +SELECT tap.col_charset_is('_caosdb_schema_unit_tests','entity_version','hash',NULL,''); +SELECT tap.col_collation_is('_caosdb_schema_unit_tests','entity_version','hash',NULL,''); + +-- COLUMN entity_version.version + +SELECT tap.has_column('_caosdb_schema_unit_tests','entity_version','version',''); +SELECT tap.col_column_type_is('_caosdb_schema_unit_tests','entity_version','version','varbinary(255)',''); +SELECT tap.col_extra_is('_caosdb_schema_unit_tests','entity_version','version','',''); +SELECT tap.col_default_is('_caosdb_schema_unit_tests','entity_version','version',NULL,''); +SELECT tap.col_charset_is('_caosdb_schema_unit_tests','entity_version','version',NULL,''); +SELECT tap.col_collation_is('_caosdb_schema_unit_tests','entity_version','version',NULL,''); + +-- COLUMN entity_version._iversion + +SELECT tap.has_column('_caosdb_schema_unit_tests','entity_version','_iversion',''); +SELECT tap.col_column_type_is('_caosdb_schema_unit_tests','entity_version','_iversion','int(10) unsigned',''); +SELECT tap.col_extra_is('_caosdb_schema_unit_tests','entity_version','_iversion','',''); +SELECT tap.col_default_is('_caosdb_schema_unit_tests','entity_version','_iversion',NULL,''); +SELECT tap.col_charset_is('_caosdb_schema_unit_tests','entity_version','_iversion',NULL,''); +SELECT tap.col_collation_is('_caosdb_schema_unit_tests','entity_version','_iversion',NULL,''); + +-- COLUMN entity_version._ipparent + +SELECT tap.has_column('_caosdb_schema_unit_tests','entity_version','_ipparent',''); +SELECT tap.col_column_type_is('_caosdb_schema_unit_tests','entity_version','_ipparent','int(10) unsigned',''); +SELECT tap.col_extra_is('_caosdb_schema_unit_tests','entity_version','_ipparent','',''); +SELECT tap.col_default_is('_caosdb_schema_unit_tests','entity_version','_ipparent','NULL',''); +SELECT tap.col_charset_is('_caosdb_schema_unit_tests','entity_version','_ipparent',NULL,''); +SELECT tap.col_collation_is('_caosdb_schema_unit_tests','entity_version','_ipparent',NULL,''); + +-- COLUMN entity_version.srid + +SELECT tap.has_column('_caosdb_schema_unit_tests','entity_version','srid',''); +SELECT tap.col_column_type_is('_caosdb_schema_unit_tests','entity_version','srid','varbinary(255)',''); +SELECT tap.col_extra_is('_caosdb_schema_unit_tests','entity_version','srid','',''); +SELECT tap.col_default_is('_caosdb_schema_unit_tests','entity_version','srid',NULL,''); +SELECT tap.col_charset_is('_caosdb_schema_unit_tests','entity_version','srid',NULL,''); +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`',''); + +-- 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 + +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',''); + +-- CONSTRAINT entity_version.entity_version_ibfk_1 + +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_update('_caosdb_schema_unit_tests','entity_version','entity_version_ibfk_1','RESTRICT',''); + +-- *************************************************************** +-- FUNCTIONS +-- *************************************************************** -- FUNCTION _caosdb_schema_unit_tests.CaosDBVersion @@ -2291,8 +2372,6 @@ SELECT tap.function_sql_data_access_is('_caosdb_schema_unit_tests','standard_uni -- PROCEDURES -- *************************************************************** -SELECT tap.routines_are('_caosdb_schema_unit_tests','PROCEDURE','`applyBackReference`,`applyPOV`,`applyRefPOV`,`applyIDFilter`,`applySAT`,`applyTransactionFilter`,`calcComplementUnion`,`calcDifference`,`calcIntersection`,`calcUnion`,`cleanUpLinCon`,`cleanUpQuery`,`copyTable`,`createTmpTable`,`createTmpTable2`,`deleteEntity`,`deleteEntityProperties`,`deleteIsa`,`deleteLinCon`,`entityACL`,`finishNegationFilter`,`finishSubProperty`,`getChildren`,`getFileIdByPath`,`getRole`,`getRules`,`initAutoIncrement`,`initBackReference`,`getFile`,`initConjunctionFilter`,`initDisjunctionFilter`,`initNegationFilter`,`initPOVRefidsTable`,`initQuery`,`insertEntity`,`getDependentEntities`,`initEmptyTargetSet`,`initEntity`,`insertLinCon`,`insertUser`,`intersectTable`,`initPOVPropertiesTable`,`initSubEntity`,`isSubtype`,`overrideDesc`,`overrideName`,`overrideType`,`raiseWarning`,`registerSubdomain`,`initSubProperty`,`insertEntityProperty`,`registerTempTableName`,`retrieveDatatype`,`retrieveEntityParents`,`retrieveGroup`,`setPassword`,`insertIsa`,`retrieveEntity`,`retrieveEntityProperties`,`showEntityAutoIncr`,`updateLinCon`,`retrieveOverrides`,`updateEntity`',''); - -- PROCEDURES _caosdb_schema_unit_tests.applyBackReference SELECT tap.has_procedure('_caosdb_schema_unit_tests','applyBackReference',''); @@ -2733,5 +2812,20 @@ SELECT tap.has_procedure('_caosdb_schema_unit_tests','updateEntity',''); SELECT tap.procedure_is_deterministic('_caosdb_schema_unit_tests','updateEntity','NO',''); SELECT tap.procedure_security_type_is('_caosdb_schema_unit_tests','updateEntity','DEFINER',''); SELECT tap.procedure_sql_data_access_is('_caosdb_schema_unit_tests','updateEntity','CONTAINS SQL',''); + +-- PROCEDURES _caosdb_schema_unit_tests.insert_single_child_version + +SELECT tap.has_procedure('_caosdb_schema_unit_tests', 'insert_single_child_version', ''); +SELECT tap.procedure_is_deterministic('_caosdb_schema_unit_tests','insert_single_child_version','NO',''); +SELECT tap.procedure_security_type_is('_caosdb_schema_unit_tests','insert_single_child_version','DEFINER',''); +SELECT tap.procedure_sql_data_access_is('_caosdb_schema_unit_tests','insert_single_child_version','CONTAINS SQL',''); + +-- PROCEDURES _caosdb_schema_unit_tests.delete_all_entity_versions + +SELECT tap.has_procedure('_caosdb_schema_unit_tests', 'delete_all_entity_versions', ''); +SELECT tap.procedure_is_deterministic('_caosdb_schema_unit_tests','delete_all_entity_versions','NO',''); +SELECT tap.procedure_security_type_is('_caosdb_schema_unit_tests','delete_all_entity_versions','DEFINER',''); +SELECT tap.procedure_sql_data_access_is('_caosdb_schema_unit_tests','delete_all_entity_versions','CONTAINS SQL',''); + CALL tap.finish(); ROLLBACK; diff --git a/tests/test_entity_versioning.sql b/tests/test_entity_versioning.sql new file mode 100644 index 0000000000000000000000000000000000000000..dd2b0f81cc3b182ccdbe60d40bd57839da64d915 --- /dev/null +++ b/tests/test_entity_versioning.sql @@ -0,0 +1,53 @@ +USE _caosdb_schema_unit_tests; +BEGIN; +CALL tap.no_plan(); + + + +-- 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"; + + +-- TEST insert_single_child_version +SELECT count(*) INTO @x FROM entity_version; +SELECT tap.eq(@x, 0, "no versions there yet"); +CALL insert_single_child_version(@EntityID, "hashbla", "versionbla", NULL, "SRIDbla"); +SELECT _ipparent INTO @x from entity_version WHERE version="versionbla"; +SELECT tap.eq(@x, NULL, "no parent for the first version"); + +-- add a second version +SELECT count(*) INTO @x FROM entity_version; +SELECT tap.eq(@x, 1, "one version there yet"); +CALL insert_single_child_version(@EntityID, "hashblub", "versionblub", "versionbla", "SRIDblub"); + +SELECT _ipparent INTO @x from entity_version WHERE version="versionblub"; +SELECT tap.eq(@x, 0, "the original entity is the parent"); + +-- error: parent does not exist +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"); + +SELECT count(*) INTO @x FROM entity_version; +SELECT tap.eq(@x, 2, "still two version there"); + + +-- TEST delete_all_entity_versions +SELECT count(*) INTO @x FROM entity_version; +SELECT tap.ok(@x > 0, "several versions in the table"); + +CALL delete_all_entity_versions(@EntityID); +SELECT count(*) INTO @x FROM entity_version; +SELECT tap.eq(@x, 0, "no versions there any more"); + + +-- TEARDOWN +DELETE FROM entities WHERE name="EntityName"; + +CALL tap.finish(); +ROLLBACK; +