Skip to content
Snippets Groups Projects
Commit e1a65e00 authored by Quazgar's avatar Quazgar
Browse files

Merge branch 'f-versioning' into 'dev'

versioning

See merge request caosdb/caosdb-mysqlbackend!12
parents 31f1be01 5d876bcd
Branches
Tags
No related merge requests found
Showing
with 1804 additions and 145 deletions
......@@ -20,7 +20,7 @@
#
services:
- mariadb:10.2
- mariadb:10.4
variables:
DEPLOY_REF: dev
CI_REGISTRY_IMAGE: $CI_REGISTRY/caosdb/caosdb-mysqlbackend/testenv:latest
......@@ -53,6 +53,7 @@ unittests:
- echo 'DATABASE_USER_HOST_LIST="%,"' >> .config
- echo "MYSQL_USER_PASSWORD=$MYSQL_ROOT_PASSWORD" >> .config
- echo "MYSQL_HOST=mariadb" >> .config
- sleep 10
- make install
- ./utils/make_db restore_db tests/example.dump.sql
- ./tests/test_utils.sh
......
......@@ -10,16 +10,53 @@ and this project adheres to [Semantic Versioning](https://semver.org/spec/v2.0.0
### Added ###
* New `feature_config` table for storing configuration of features as key-value
pairs. Currently only used by the ENTITY_VERSIONING feature for switching
versioning on or off. Convenient function `is_feature_config` for checking
whether the `feature_config` table has a particular value.
* New `transactions` table. This is necessary for the ENTITY_VERSIONING feature
and will replace the `transaction_log` table in the future.
* Feature ENTITY_VERSIONING (experimental)
Switch off this feature with `DELETE FROM feature_config WHERE
_key="ENTITY_VERSIONING"` and switch on with `INSERT INTO feature_config
(_key, _value) VALUES ("ENTITY_VERSIONING", "ENABLED")`. This feature comes
with a lot of additions to the API. E.g.
* New `entity_version`.
* All `*_data` tables have a new twin, the `archive_*_data` table, where all
old versions of entities are stored. The `*_data` tables only contain the
data of the latest version.
* Additional `archive_isa` for the history entities' parents.
* Additional `_iversion` column for the `reference_data` table for storing
references to particular versions of an entity.
* New `setFileProperties` and `retrieveQueryTemplateDef` procedures which reduce server code and let the
backend decide which tables to use. Also, this is necessary for the
versioning, because these procedures behave differently depending on the
ENTITY_VERSIONING feature being enabled or disabled.
* Several functions and procedures for the interaction with the
`entity_version` table and the `transactions` table. E.g.
`insert_single_child_version`, `delete_all_entity_versions`,
`get_iversion`, `get_primary_parent_version`, `get_version_timestamp`,
`get_head_version`, `get_head_relative`, `get_version_history`.
The versions are tracked internally by the `_iversion` field which is an
integer and which should not be used outside of the backend.
* New makefile targets for testing with MariaDB instance from Docker image: call
`make test-docker` to temporarily start a Docker container with MariaDB which
will be used for the unit tests.
### Changed ###
* Removed `getFile` procedure.
### Deprecated ###
* Table `transaction_log` is deprecated. The functionality is being replaced by the `transactions` table.
### Fixed ###
* POV with the 'name' property, e.g. `FIND ENTITY WITH name = something`
[caosdb-server#51](https://gitlab.com/caosdb/caosdb-server/-/issues/51)
- Fixed several bugs when an Entity inherits from itself (#18, caosdb-server #85).
- Bug in `updateEntity.sql` (when updating the primary name without a prior call
* Fixed several bugs when an Entity inherits from itself (#18, caosdb-server #85).
* Bug in `updateEntity.sql` (when updating the primary name without a prior call
to `deleteEntityProperties`). Same thing for `deleteEntity`.
### Security ###
......@@ -36,6 +36,40 @@
be lost afterwards.** And no, there is *no* additional prompt to ask if you
are sure. If you `make drop-...`, you *actually* delete the database.
## Versioning
The versioning feature is still experimental. Therefore it is possible to turn
if on and off with a patch file and a special property.
### Procedures and Functions
The procedures which need to behave differently if the versioning is on or off
check the return value of `is_feature_config("ENTITY_VERSIONING", "ENABLED")`.
The `is_feature_config` function checks the `feature_config` table, which is
a key-value store.
Turn off versioning: Run `UPDATE feature_config SET _value = "DISABLED" WHERE
_key = "ENTITY_VERSIONING";` on your database.
Turn on versioning again: Run `UPDATE feature_config SET _value = "ENABLED"
WHERE _key = "ENTITY_VERSIONING";` on your database.
### Data
When the versioning patch is installed, the versioning is turned on by default
and all old entities become versioned entities with their current version as
the oldest known version. That is, they all need an entry in the
`entity_version` table. These entries are generated by the `_fix_unversioned`
procedure.
If you want to turn off the versioning for the time being you can just turn it
off for the procedures as described above. You should also empty the
`entity_version` table because the `_fix_unversioned` procedure is only
designed to cope with entities which do not have any versioning information at
all. The already recorded versioning information is of course lost then! If you
switch on the versioning at some point in the future, the history begins anew
with the then current version of the stored entities.
## Unit tests
* We use [MyTAP-1.0](https://hepabolu.github.io/mytap/) for unit tests.
......
......@@ -56,6 +56,20 @@ These tables share (generally) the same set of columns:
- `pidx` :: The property index, becomes nonzero when a property occurs more than
once in an entity.
### `name_data` ###
This table is used to name RecordTypoes, Records, Properties etc. The column `property_id` has the
value 20, because that is the entity ID for names:
```sql
> SELECT * FROM entities WHERE id=20;
+----+-------------------+----------+------+
| id | description | role | acl |
+----+-------------------+----------+------+
| 20 | Name of an entity | PROPERTY | 0 |
+----+-------------------+----------+------+
```
## data_type ##
The type of properties is stored here. The columns are:
- `domain_id` :: Property identitification, same as for plain data?
......@@ -71,6 +85,56 @@ The type of properties is stored here. The columns are:
- `hash` :: Hash of the file contents, as binary. **TODO** Which algorithm?
- `checked_timestamp` :: Timestamp when last checked?
## `feature_config` ##
+-------------------+---------+
| _key | _value |
+-------------------+---------+
| ENTITY_VERSIONING | ENABLED |
+-------------------+---------+
A key-value store for features. Use the `is_feature_config` procedure to check for the status of
specific features.
## Versioning tables ##
There are a few extra tables for implementing versioning. Also there is a special column
`value_iversion` in the `reference_data` table which stores the version of the referenced entity at
the time of the version. If `value_iversion` is NULL, no specific version is stored.
### transactions ###
Replacement for `transaction_log`, holds ID, user and time of transaction:
- `srid` :: Server request ID, used to identify transactions
- `username` :: User name
- `realm` :: Realm for which the user name is valid
- `seconds` :: Time of transaction: seconds
- `nanos` :: Time of transaction: sub-second time resolution
### `entity_version` ###
Versioning info for entities:
- `entity_id` :: persistent ID of the entity
- `hash` :: Hash, for future use.
- `version` :: External version string, may be globally unique. Should be used by API calls.
- `_iversion` :: Version ID for this entity for internal use, typically an incremental counter,
starting with 1
- `_ipparent` :: Primary parent ID (internal) for this version, i.e. predecessor
- `srid` :: Server request / transaction ID which created this version
### `archive_foo_data` ###
Older (i.e. not current) data value, from previous versions of an entity.
- `domain_id` :: Same as in `foo_data`.
- `entity_id` :: Same as in `foo_data`.
- `property_id` :: Same as in `foo_data`.
- `value` :: The value at the given version.
- `status` :: The value at the given version.
- `pidx` :: Same as in `foo_data`.
- `_iversion` :: Version index of this version.
- ... :: Data type specific columns may also be there.
## TODO ##
- entity_acl
......
......@@ -51,3 +51,21 @@ drop-%:
.PHONY: test
test:
./utils/make_db test --fresh
# Run tests with a database which is started in a Docker container
.PHONY: test-docker
test-docker:
@docker kill caosdb-mysqlserver-test || true
@docker container rm caosdb-mysqlserver-test || true
@docker run --name caosdb-mysqlserver-test -p "3306:3306" \
-e MYSQL_ROOT_PASSWORD="pass-for-test" -d mariadb
@sleep 10
MAINPATH=$(realpath tests/docker_env) utils/make_db test --fresh
@docker kill caosdb-mysqlserver-test
@docker container rm caosdb-mysqlserver-test
# if automatic stopping failed
.PHONY: test-docker-stop
test-docker-stop:
docker kill caosdb-mysqlserver-test
docker container rm caosdb-mysqlserver-test
/*
* 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/>.
*/
-- Create a fresh `feature_config` table and the `is_feature_config` function.
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 //
/*
* 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
-- SRID needs to be invented in this case, because original server request ID is
-- not known (any more).
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 the fallback 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; -- only latest transaction
-- insert single (latest) version into entity_version
INSERT INTO entity_version (entity_id, hash, version, _iversion,
_ipparent, srid)
SELECT tmp.entity_id, tmp.hash, tmp.version, tmp._iversion,
tmp._ipparent, tmp.srid
FROM (
SELECT
l.entity_id AS entity_id,
NULL as hash,
SHA1(UUID()) as version,
1 AS _iversion,
NULL AS _ipparent,
t.srid AS srid,
t.seconds AS seconds,
t.nanos AS nanos
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 AND unversioned_id >= 100
UNION SELECT
unversioned_id AS entity_id,
NULL AS hash,
SHA1(UUID()) AS version,
1 AS _iversion,
NULL AS _ipparent,
t.srid AS srid,
t.seconds AS seconds,
t.nanos AS nanos
FROM transactions AS t
WHERE t.seconds = 0 AND t.nanos = 0 AND unversioned_id < 100
) AS tmp ORDER BY tmp.seconds DESC, tmp.nanos DESC LIMIT 1;
END LOOP;
CLOSE entities_cur;
END;
//
delimiter ;
#!/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
# 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
#
# new entity_version table
# Update mysql schema to version v3.0.0-rc2
NEW_VERSION="v3.0.0-rc2"
OLD_VERSION="v3.0.0-rc1"
if [ -z "$UTILSPATH" ]; then
UTILSPATH="../utils"
fi
. $UTILSPATH/patch_header.sh $*
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
mysql_execute "CALL _fix_unversioned()"
mysql_execute "DROP PROCEDURE _fix_unversioned"
update_version $NEW_VERSION
success
/*
* 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/>.
*/
-- Create tables for versioning.
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;
CREATE TABLE transactions (
srid VARBINARY(255) PRIMARY KEY, -- server request ID ?
username VARBINARY(255) NOT NULL, -- who did the transactions: username
realm VARBINARY(255) NOT NULL, -- who did the transactions: realm
seconds BIGINT UNSIGNED NOT NULL, -- time of transaction: seconds
nanos INT(10) UNSIGNED NOT NULL -- time of transaction: sub-second time resolution
) ENGINE=InnoDB;
-- TODO remove ON DELETE CASCADE when feature is stable.
CREATE TABLE entity_version (
entity_id INT UNSIGNED NOT NULL,
hash VARBINARY(255) DEFAULT NULL,
version VARBINARY(255) NOT NULL, -- external version identifier, may be globally unique
_iversion INT UNSIGNED NOT NULL, -- internal version ID, typically an incremental counter
_ipparent INT UNSIGNED NULL, -- (internal) ID of the primary parent, i.e. of the predecessor
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_version-e-v` (`entity_id`, `version`)
) ENGINE=InnoDB;
ALTER TABLE reference_data
ADD COLUMN `value_iversion` INT UNSIGNED DEFAULT NULL,
ADD FOREIGN KEY (`value`, `value_iversion`) REFERENCES
entity_version (`entity_id`, `_iversion`);
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,
value_iversion INT UNSIGNED DEFAULT 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 `archive_name_overrides-d-e-p-v` (`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 `archive_desc_overrides-d-e-p-v` (`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 `archive_data_type-d-e-p-v` (`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 `archive_collection_type-d-e-p-v` (`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,
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;
ALTER IGNORE TABLE collection_type ADD UNIQUE KEY `collection_type-d-e-p` (`domain_id`, `entity_id`, `property_id`);
INSERT INTO feature_config (_key, _value) VALUES ("ENTITY_VERSIONING", "ENABLED");
......@@ -45,14 +45,32 @@ BEGIN
DELETE FROM files where file_id=EntityID;
-- delete datatype stuff
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 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 primary name (in case this is called without a prior call to deleteEntityProperties)
DELETE FROM name_data WHERE domain_id = 0 AND entity_id = EntityID AND property_id = 20;
DELETE FROM name_data
WHERE domain_id = 0
AND entity_id = EntityID
AND property_id = 20;
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);
-- clean up unused acl
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;
//
......
......@@ -4,6 +4,8 @@
*
* Copyright (C) 2018 Research Group Biomedical Physics,
* Max-Planck-Institute for Dynamics and Self-Organization Göttingen
* 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
......@@ -26,9 +28,127 @@ delimiter //
CREATE PROCEDURE db_2_0.deleteEntityProperties(in EntityID INT UNSIGNED)
BEGIN
DECLARE IVersion INT UNSIGNED DEFAULT NULL;
CALL deleteIsa(EntityID);
IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN
SELECT max(e._iversion) INTO IVersion -- What's the latest version?
FROM entity_version AS e
WHERE e.entity_id = EntityID;
-- Copy the rows from *_data to archive_*_data ---------------------
INSERT INTO archive_reference_data (domain_id, entity_id,
property_id, value, value_iversion, status, pidx, _iversion)
SELECT domain_id, entity_id, property_id, value, value_iversion,
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
......@@ -47,14 +167,16 @@ 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 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;
......
......@@ -5,6 +5,7 @@
* Copyright (C) 2018 Research Group Biomedical Physics,
* Max-Planck-Institute for Dynamics and Self-Organization Göttingen
* 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
......@@ -41,8 +42,26 @@ Child entity for which all parental relations should be deleted.
*/
CREATE PROCEDURE db_2_0.deleteIsa(IN EntityID INT UNSIGNED)
BEGIN
DECLARE IVersion INT UNSIGNED DEFAULT NULL;
DELETE FROM isa_cache WHERE child=EntityID or rpath=EntityID or rpath LIKE concat('%>',EntityID) or rpath LIKE concat('%>', EntityID, '>%');
IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN
SELECT max(_iversion) INTO IVersion
FROM entity_version
WHERE entity_id = EntityID;
-- move to archive_isa before deleting (only direct child-parent relations)
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 = EntityID;
END IF;
DELETE FROM isa_cache
WHERE child = EntityID
OR rpath = EntityID
OR rpath LIKE concat('%>', EntityID)
OR rpath LIKE concat('%>', EntityID, '>%');
END;
//
......
/*
* 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/>.
*/
delimiter //
DROP PROCEDURE IF EXISTS db_2_0.insert_single_child_version //
/**
* Creates a new version record in the `entity_version` table.
*
* Parameters
* ----------
* EntityID
* The ID of the versioned entity.
* Hash
* A hash of the entity. This is currently not implemented properly and only
* there for future use.
* Version
* The new version ID of the entity, must be produced by the caller. Must be unique for each
* EntityID.
* Parent
* The version ID of the primary parent (i.e. predecessor). May be NULL; but if given, it must
* exist.
* Transaction
* The transaction ID which created this entity version (by inserting
* or updating an entity).
*/
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 = 1;
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 //
/**
* Remove all records in the entity_version table for the given entity.
*
* Parameters
* ----------
* EntityID
* The id of the versioned entity.
*/
CREATE PROCEDURE db_2_0.delete_all_entity_versions(
in EntityID INT UNSIGNED)
BEGIN
DELETE FROM entity_version WHERE entity_id = EntityID;
END;
//
DROP FUNCTION IF EXISTS db_2_0.get_iversion //
/**
* Get the internal version id (an integer) of the (API-)version id.
*
* Parameters
* ----------
* EntityID
* The entity's id.
* Version
* The (official, externally used) version id.
*
* Returns
* -------
* The internal version id.
*/
CREATE FUNCTION db_2_0.get_iversion(
EntityID INT UNSIGNED,
Version VARBINARY(255))
RETURNS INT UNSIGNED
READS SQL DATA
BEGIN
RETURN (
SELECT e._iversion
FROM entity_version AS e
WHERE e.entity_id = EntityID
AND e.version = Version
);
END;
//
DROP FUNCTION IF EXISTS db_2_0.get_primary_parent_version //
/**
* Get the version ID of the primary parent (i.e. predecessor) of a version.
*
* Parameters
* ----------
* EntityID
* The entity id.
* Version
* The version id.
*
* Returns
* -------
* The id of the given version's primary parent version.
*/
CREATE FUNCTION db_2_0.get_primary_parent_version(
EntityID INT UNSIGNED,
Version 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 = EntityID
AND e.version = Version
);
END;
//
DROP FUNCTION IF EXISTS db_2_0.get_version_timestamp //
/**
* Get the timestamp of a version by retrieving the timestamp of the
* transaction which created the version.
*
* Parameters
* ----------
* EntityID
* The entity id.
* Version
* The version id.
*
* Returns
* -------
* The versions' timestamp in <seconds-since-epoch>.<nanoseconds> format.
* Note that the dot `.` here is not necessarily a decimal separator.
*/
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.version = Version
);
END;
//
DROP FUNCTION IF EXISTS db_2_0.get_head_version //
/**
* Get the version id of the HEAD of an entity.
*
* Parameters
* ----------
* EntityID
* The entity id.
*
* Returns
* -------
* The version id of the HEAD.
*/
CREATE FUNCTION db_2_0.get_head_version(
EntityID INT UNSIGNED)
RETURNS VARBINARY(255)
READS SQL DATA
BEGIN
RETURN get_head_relative(EntityID, 0);
END;
//
DROP FUNCTION IF EXISTS db_2_0.get_head_relative //
/**
* Get the id of a version which is specified relative to the HEAD of an
* entity.
*
* Parameters
* ----------
* EntityID
* The entity id.
* Offset
* Distance in the sequence of primary parents of the entity. E.g. `0` is the
* HEAD itself. `1` is the primary parent of the HEAD. `2` is the primary
* parent of the primary parent of the HEAD, and so on.
*
* Returns
* -------
* The version id of the HEAD.
*/
CREATE FUNCTION db_2_0.get_head_relative(
EntityID INT UNSIGNED,
Offset INT UNSIGNED)
RETURNS VARBINARY(255)
READS SQL DATA
BEGIN
-- This implementation assumes that the distance from the head equals the
-- difference between the _iversion numbers. This will not be correct anymore
-- as soon as branches may split and merge. Then, a walk over the primary
-- parents (_ipparent) will be necessary.
RETURN (
SELECT e.version
FROM entity_version AS e
WHERE e.entity_id = EntityID
ORDER BY e._iversion DESC
LIMIT 1 OFFSET Offset
);
END;
//
DROP FUNCTION IF EXISTS db_2_0._get_version //
/**
* The inverse function of get_iversion. Resolves the version id.
*
* Parameters
* ----------
* EntityID
* The entity id.
* IVersion
* Internal version id (integer).
*
* Returns
* -------
* The version id.
*/
CREATE FUNCTION db_2_0._get_version(
EntityID INT UNSIGNED,
IVersion INT UNSIGNED)
RETURNS VARBINARY(255)
READS SQL DATA
BEGIN
RETURN (
SELECT version FROM entity_version
WHERE entity_id = EntityID
AND _iversion = IVersion
);
END;
//
DROP PROCEDURE IF EXISTS db_2_0.get_version_history //
/**
* Select version timestamps of an entity.
*
* Parameters
* ----------
* EntityID
* The entity id.
*
* Selects
* -------
* Tuples (child, parent, child_seconds, child_nanos). `child` and `parent` are
* version IDs.
*/
CREATE PROCEDURE db_2_0.get_version_history(
in EntityID INT UNSIGNED)
BEGIN
-- retrieve root(s) (initial versions)
SELECT c.version AS child,
NULL as parent,
t.seconds AS child_seconds,
t.nanos AS child_nanos
FROM entity_version AS c INNER JOIN transactions as t
ON ( c.srid = t.srid )
WHERE c.entity_id = EntityID
AND c._ipparent is Null
-- TODO This first SELECT statement is necessary because the second one
-- does not return the root. However, this should be doable in one go with
-- a left join instead of an inner join(?).
-- retrieve branches (later versions)
UNION SELECT c.version AS child,
p.version AS parent,
t.seconds AS child_seconds,
t.nanos AS child_nanos
FROM entity_version AS p
INNER JOIN entity_version as c
INNER JOIN transactions AS t
ON (c._ipparent = p._iversion
AND c.entity_id = p.entity_id
AND t.srid = c.srid)
WHERE p.entity_id = EntityID;
END;
//
DROP PROCEDURE IF EXISTS set_transaction //
/**
* Called when a new transaction begins. Inserts the transaction metadata into
* the transactions table.
*
* Parameters
* ----------
* srid
* The server-generated Server Request ID.
* username
* The username of the subject who/which is responsible for the transaction.
* realm
* The realm of the subject.
* seconds
* Unix timestamp (seconds).
* nanos
* Nanoseconds precision for the timestamp.
*/
CREATE PROCEDURE set_transaction(
srid VARBINARY(255),
username VARCHAR(255),
realm VARCHAR(255),
seconds BIGINT UNSIGNED,
nanos INT(10) UNSIGNED)
BEGIN
SET @SRID = srid; -- Make the transaction / server request ID globally available.
INSERT INTO transactions (srid, username, realm, seconds, nanos)
VALUES (srid, username, realm, seconds, nanos);
END //
DROP PROCEDURE IF EXISTS setFileProperties //
/**
* Insert/Update file properties.
*
* If ENTITY_VERSIONING is enabled the old file properties are moved to
* `archive_files`.
*
* Parameters
* ----------
* EntityID
* The file's id.
* FilePath
* Path of the file in the internal file system. If NULL, an existing file
* entity is simply deleted.
* FileSize
* Size of the file in bytes.
* FileHash
* A Sha512 Hash of the file.
*/
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 //
DROP PROCEDURE IF EXISTS retrieveQueryTemplateDef //
/**
* Select a query string from the templates tables.
*
* Parameters
* ----------
* EntityID
* The QueryTemplate's id.
* Version
* The QueryTemplate's version's id.
*
* Returns
* -------
* Tuple (definition). A CQL query string (-fragment) which defines this
* QueryTemplate.
*/
CREATE PROCEDURE retrieveQueryTemplateDef (
in EntityID INT UNSIGNED,
in Version VARBINARY(255))
retrieveQueryTemplateDefBody: BEGIN
DECLARE IVersion INT UNSIGNED DEFAULT NULL;
DECLARE IsHead BOOLEAN DEFAULT TRUE;
IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN
-- Are we at the head?
IF Version IS NOT NULL THEN
SELECT get_head_version(EntityID) = Version INTO IsHead;
END IF;
IF IsHead IS FALSE THEN
-- TODO Use get_iversion(EntityID, Version) instead? Or will that be much slower?
SELECT e._iversion INTO IVersion
FROM entity_version as e
WHERE e.entity_id = EntityID
AND e.version = Version;
IF IVersion IS NULL THEN
-- RETURN EARLY - Version does not exist.
LEAVE retrieveQueryTemplateDefBody;
END IF;
SELECT definition
FROM archive_query_template_def
WHERE id = EntityID
AND _iversion = IVersion;
LEAVE retrieveQueryTemplateDefBody;
END IF;
END IF;
SELECT definition
FROM query_template_def
WHERE id = EntityID;
END //
delimiter ;
......@@ -5,6 +5,7 @@
* Copyright (C) 2018 Research Group Biomedical Physics,
* Max-Planck-Institute for Dynamics and Self-Organization Göttingen
* Copyright (C) 2020 IndiScale GmbH <info@indiscale.com>
* Copyright (C) 2020 Timm Fitschen <t.fitschen@indiscale
*
* This program is free software: you can redistribute it and/or modify
* it under the terms of the GNU Affero General Public License as
......@@ -39,11 +40,19 @@ Currently one of 'RECORDTYPE', 'RECORD', 'FILE', 'DOMAIN', 'PROPERTY',
'DATATYPE', 'ROLE', 'QUERYTEMPLATE'
ACL : VARBINARY(65525)
Select
======
A tuple (EntityID, Version)
*/
CREATE PROCEDURE db_2_0.insertEntity(in EntityName VARCHAR(255), in EntityDesc TEXT, in EntityRole VARCHAR(255), in ACL VARBINARY(65525))
BEGIN
DECLARE NewEntityID INT UNSIGNED DEFAULT NULL;
DECLARE NewACLID INT UNSIGNED DEFAULT NULL;
DECLARE Hash VARBINARY(255) DEFAULT NULL;
DECLARE Version VARBINARY(255) DEFAULT NULL;
DECLARE Transaction VARBINARY(255) DEFAULT NULL;
-- insert the acl. the new acl id is being written (c-style) into the
-- variable NewACLID.
......@@ -56,6 +65,13 @@ BEGIN
-- ... and return the generated id
SET NewEntityID = LAST_INSERT_ID();
IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN
-- TODO this is transaction-scoped variable. Is this a good idea?
SET Transaction = @SRID;
SET Version = SHA1(UUID());
CALL insert_single_child_version(NewEntityID, Hash, Version, Null, Transaction);
END IF;
-- insert the name of the entity into name_data table
-- 20 is the (hard-coded) id of the 'name' property.
IF EntityName IS NOT NULL THEN
......@@ -64,7 +80,7 @@ BEGIN
VALUES (0, NewEntityID, 20, EntityName, "FIX", 0);
END IF;
Select NewEntityID as EntityID;
SELECT NewEntityID as EntityID, Version as Version;
END;
//
......
......@@ -4,6 +4,8 @@
*
* Copyright (C) 2018 Research Group Biomedical Physics,
* Max-Planck-Institute for Dynamics and Self-Organization Göttingen
* Copyright (C) 2020 IndiScale GmbH <info@indiscale.com>
* Copyright (C) 2020 Timm Fitschen <t.fitschen@indiscale
*
* This program is free software: you can redistribute it and/or modify
* it under the terms of the GNU Affero General Public License as
......@@ -23,8 +25,23 @@
DROP PROCEDURE IF EXISTS db_2_0.insertEntityProperty;
delimiter //
CREATE PROCEDURE db_2_0.insertEntityProperty(in DomainID INT UNSIGNED, in EntityID INT UNSIGNED, in PropertyID INT UNSIGNED, in Datatable VARCHAR(255), in PropertyValue TEXT, in PropertyUnitSig BIGINT, in PropertyStatus VARCHAR(255), in NameOverride VARCHAR(255), in DescOverride TEXT, in datatypeOverride INT UNSIGNED, in Collection VARCHAR(255), in PropertyIndex INT UNSIGNED)
CREATE PROCEDURE db_2_0.insertEntityProperty(
in DomainID INT UNSIGNED,
in EntityID INT UNSIGNED,
in PropertyID INT UNSIGNED,
in Datatable VARCHAR(255),
in PropertyValue TEXT,
in PropertyUnitSig BIGINT,
in PropertyStatus VARCHAR(255),
in NameOverride VARCHAR(255),
in DescOverride TEXT,
in DatatypeOverride INT UNSIGNED,
in Collection VARCHAR(255),
in PropertyIndex INT UNSIGNED)
BEGIN
DECLARE ReferenceValueIVersion INT UNSIGNED DEFAULT NULL;
DECLARE ReferenceValue INT UNSIGNED DEFAULT NULL;
DECLARE AT_PRESENT INTEGER DEFAULT NULL;
CASE Datatable
WHEN 'double_data' THEN
......@@ -43,10 +60,28 @@ BEGIN
VALUES
(DomainID, EntityID, PropertyID, SUBSTRING_INDEX(PropertyValue, 'UTC', 1), IF(SUBSTRING_INDEX(PropertyValue, 'UTC', -1)='',NULL,SUBSTRING_INDEX(PropertyValue, 'UTC', -1)), PropertyStatus, PropertyIndex);
WHEN 'reference_data' THEN
-- special handling if versioning enabled and specific version of referenced entity is given.
SET AT_PRESENT=LOCATE("@", PropertyValue);
IF is_feature_config("ENTITY_VERSIONING", "ENABLED") AND AT_PRESENT > 0 THEN
SET ReferenceValue = SUBSTRING_INDEX(PropertyValue, '@', 1);
SET ReferenceValueIVersion = get_iversion(ReferenceValue,
SUBSTRING_INDEX(PropertyValue, '@', -1));
-- TODO raise error when @ present but iversion is null
IF ReferenceValueIVersion IS NULL THEN
SELECT 0 from `ReferenceValueIVersion_WAS_NULL`;
END IF;
ELSE
SET ReferenceValue = PropertyValue;
END IF;
INSERT INTO reference_data
(domain_id, entity_id, property_id, value, status, pidx)
(domain_id, entity_id, property_id, value, value_iversion, status,
pidx)
VALUES
(DomainID, EntityID, PropertyID, PropertyValue, PropertyStatus, PropertyIndex);
(DomainID, EntityID, PropertyID, ReferenceValue,
ReferenceValueIVersion, PropertyStatus, PropertyIndex);
WHEN 'enum_data' THEN
INSERT INTO enum_data
(domain_id, entity_id, property_id, value, status, pidx)
......
......@@ -31,13 +31,15 @@
DROP PROCEDURE IF EXISTS db_2_0.registerSubdomain;
delimiter //
CREATE PROCEDURE db_2_0.registerSubdomain(in Count INT UNSIGNED)
CREATE PROCEDURE db_2_0.registerSubdomain(in amount INT UNSIGNED)
BEGIN
DECLARE ED INTEGER DEFAULT NULL;
Select COUNT(id) INTO ED FROM entities WHERE Role='DOMAIN' AND id!=0;
WHILE ED < Count DO
INSERT INTO entities (description, role, acl) VALUES ("Multipurpose subdomain", 'DOMAIN', 0);
SELECT COUNT(id) INTO ED FROM entities WHERE Role='DOMAIN' AND id!=0;
WHILE ED < amount DO
INSERT INTO entities (description, role, acl) VALUES
(NULL, 'DOMAIN', 0);
SET ED = ED + 1;
END WHILE;
......
......@@ -4,6 +4,8 @@
*
* Copyright (C) 2018 Research Group Biomedical Physics,
* Max-Planck-Institute for Dynamics and Self-Organization Göttingen
* Copyright (C) 2020 IndiScale GmbH <info@indiscale.com>
* Copyright (C) 2020 Timm Fitschen <t.fitschen@indiscale
*
* This program is free software: you can redistribute it and/or modify
* it under the terms of the GNU Affero General Public License as
......@@ -27,31 +29,168 @@ delimiter //
drop procedure if exists db_2_0.retrieveEntity //
create procedure db_2_0.retrieveEntity(in EntityID INT UNSIGNED)
BEGIN
/**
* Select the content of an entity.
*
* By default the head is selected, but a specific version may be given.
*
* Parameters
* ----------
* EntityID
* The entity's id.
* Version
* The version id. In this procedure only, the version may also be given as
* `HEAD` for the latest version or as `HEAD~n`, which retrieves the n-th
* ancestor of `HEAD`.
*
*/
create procedure db_2_0.retrieveEntity(
in EntityID INT UNSIGNED,
in Version VARBINARY(255))
retrieveEntityBody: 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 CollectionName VARCHAR(255) DEFAULT NULL;
DECLARE VersionSeconds BIGINT UNSIGNED DEFAULT NULL;
DECLARE VersionNanos INT(10) UNSIGNED DEFAULT NULL;
DECLARE IsHead BOOLEAN DEFAULT TRUE;
DECLARE IVersion INT UNSIGNED DEFAULT NULL;
IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN
-- Find out head-ness and version
IF Version IS NULL OR UPPER(Version) = "HEAD" THEN
SET Version = get_head_version(EntityID);
ELSEIF UPPER(LEFT(Version, 5)) = "HEAD~" THEN
SET IsHead = FALSE;
SET Version = get_head_relative(EntityID, SUBSTR(Version, 6));
ELSE
SELECT get_head_version(EntityID) = Version INTO IsHead;
END IF;
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;
IF IsHead IS FALSE THEN
SET IVersion=get_iversion(EntityID, Version);
IF IVersion IS NULL THEN
-- RETURN EARLY - Version does not exist.
SELECT 0 WHERE 0 = 1;
LEAVE retrieveEntityBody;
END IF;
SELECT path, size, HEX(hash)
INTO FilePath, FileSize, FileHash
FROM archive_files
WHERE file_id = EntityID
AND _iversion = IVersion
LIMIT 1;
SELECT datatype
INTO DatatypeID
FROM archive_data_type
WHERE domain_id = 0
AND entity_id = 0
AND property_id = EntityID
AND _iversion = IVersion
LIMIT 1;
SELECT collection
INTO CollectionName
FROM archive_collection_type
WHERE domain_id = 0
AND entity_id = 0
AND property_id = EntityID
AND _iversion = IVersion
LIMIT 1;
-- Final select before returning
SELECT
( SELECT value FROM
( SELECT value FROM name_data
WHERE domain_id = 0
AND entity_ID = DatatypeID
AND property_id = 20
UNION SELECT DatatypeID AS value
) AS tmp LIMIT 1 ) AS Datatype,
CollectionName AS Collection,
EntityID AS EntityID,
( SELECT value FROM archive_name_data
WHERE domain_id = 0
AND entity_ID = EntityID
AND property_id = 20
AND _iversion = IVersion
-- LIMIT 1 -- TODO Remove this line if all tests pass.
) 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 archive_entities AS e
WHERE e.id = EntityID
AND e._iversion = IVersion
LIMIT 1;
-- RETURN EARLY
LEAVE retrieveEntityBody;
END IF;
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 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 value FROM name_data WHERE domain_id = 0 AND entity_ID = DatatypeID AND property_id = 20 LIMIT 1) as Datatype,
CollectionName as Collection,
EntityID as EntityID,
(SELECT value FROM name_data WHERE domain_id = 0 AND entity_ID = EntityID AND property_id = 20 LIMIT 1) 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 LIMIT 1) as ACL
from entities e where id = EntityID LIMIT 1;
SELECT
( SELECT value FROM name_data
WHERE domain_id = 0
AND entity_ID = DatatypeID
AND property_id = 20 LIMIT 1 ) AS Datatype,
CollectionName AS Collection,
EntityID AS EntityID,
( SELECT value FROM name_data
WHERE domain_id = 0
AND entity_ID = EntityID
AND property_id = 20 LIMIT 1) 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;
//
......
......@@ -4,6 +4,8 @@
*
* Copyright (C) 2018 Research Group Biomedical Physics,
* Max-Planck-Institute for Dynamics and Self-Organization Göttingen
* 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
......@@ -24,13 +26,156 @@
DROP PROCEDURE IF EXISTS db_2_0.retrieveOverrides;
delimiter //
CREATE PROCEDURE db_2_0.retrieveOverrides(in DomainID INT UNSIGNED, in EntityID INT UNSIGNED)
BEGIN
CREATE PROCEDURE db_2_0.retrieveOverrides(
in DomainID INT UNSIGNED,
in EntityID INT UNSIGNED,
in Version VARBINARY(255))
retrieveOverridesBody: BEGIN
SELECT NULL as collection_override, name as name_override, NULL as desc_override, NULL as type_override, entity_id, property_id from name_overrides where domain_id=DomainID and entity_id=EntityID UNION ALL
SELECT NULL as collection_override, NULL as name_override, description as desc_override, NULL as type_override, entity_id, property_id from desc_overrides where domain_id=DomainID and entity_id=EntityID UNION ALL
SELECT NULL as collection_override, NULL as name_override, NULL as desc_override, (SELECT value FROM name_data WHERE domain_id = 0 AND entity_ID = datatype AND property_id = 20) as type_override, entity_id, property_id from data_type where domain_id=DomainID and entity_id=EntityID UNION ALL
SELECT collection as collection_override, NULL as name_override, NULL as desc_override, NULL as type_override, entity_id, property_id from collection_type where domain_id=DomainID and entity_id=EntityID;
DECLARE IVersion INT UNSIGNED DEFAULT NULL;
DECLARE IsHead BOOLEAN DEFAULT TRUE;
IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN
IF Version IS NOT NULL THEN
IF DomainID = 0 THEN
SELECT get_head_version(EntityID) = Version INTO IsHead;
ELSE
SELECT get_head_version(DomainID) = Version INTO IsHead;
END IF;
END IF;
IF IsHead IS FALSE THEN
SELECT e._iversion INTO IVersion
FROM entity_version as e
WHERE ((e.entity_id = EntityID AND DomainID = 0)
OR (e.entity_id = DomainID))
AND e.version = Version;
IF IVersion IS NULL THEN
-- RETURN EARLY - Version does not exist.
LEAVE retrieveOverridesBody;
END IF;
-- name
SELECT
NULL AS collection_override,
name AS name_override,
NULL AS desc_override,
NULL AS type_override,
entity_id,
property_id
FROM archive_name_overrides
WHERE domain_id = DomainID
AND entity_id = EntityID
AND _iversion = IVersion
UNION ALL
-- description
SELECT
NULL AS collection_override,
NULL AS name_override,
description AS desc_override,
NULL AS type_override,
entity_id,
property_id
FROM archive_desc_overrides
WHERE domain_id = DomainID
AND entity_id = EntityID
AND _iversion = IVersion
UNION ALL
-- data type
SELECT
NULL AS collection_override,
NULL AS name_override,
NULL AS desc_override,
( SELECT value FROM
( SELECT value FROM name_data
WHERE domain_id = 0
AND entity_ID = datatypeID
AND property_id = 20
UNION SELECT datatype AS value
) AS tmp LIMIT 1 ) AS type_override,
entity_id,
property_id
FROM archive_data_type
WHERE domain_id = DomainID
AND entity_id = EntityID
AND _iversion = IVersion
UNION ALL
-- collection
SELECT
collection AS collection_override,
NULL AS name_override,
NULL AS desc_override,
NULL AS type_override,
entity_id,
property_id
FROM archive_collection_type
WHERE domain_id = DomainID
AND entity_id = EntityID
AND _iversion = IVersion;
LEAVE retrieveOverridesBody;
END IF;
END IF;
SELECT
NULL AS collection_override,
name AS name_override,
NULL AS desc_override,
NULL AS type_override,
entity_id,
property_id
FROM name_overrides
WHERE domain_id = DomainID
AND entity_id = EntityID
UNION ALL
SELECT
NULL AS collection_override,
NULL AS name_override,
description AS desc_override,
NULL AS type_override,
entity_id,
property_id
FROM desc_overrides
WHERE domain_id = DomainID
AND entity_id = EntityID
UNION ALL
SELECT
NULL AS collection_override,
NULL AS name_override,
NULL AS desc_override,
( SELECT value FROM name_data
WHERE domain_id = 0
AND entity_ID = datatype
AND property_id = 20 LIMIT 1 ) AS type_override,
entity_id,
property_id
FROM data_type
WHERE domain_id = DomainID
AND entity_id = EntityID
UNION ALL
SELECT
collection AS collection_override,
NULL AS name_override,
NULL AS desc_override,
NULL AS type_override,
entity_id,
property_id
FROM collection_type
WHERE domain_id = DomainID
AND entity_id = EntityID;
END;
......
0% Loading or .
You are about to add 0 people to the discussion. Proceed with caution.
Please register or to comment