Skip to content
Snippets Groups Projects
Commit 5fb99009 authored by Timm Fitschen's avatar Timm Fitschen
Browse files

Merge branch 'f-query-version' into 'dev'

f-query-version -> dev

See merge request caosdb/caosdb-mysqlbackend!18
parents 6d11e4f5 f4f1d250
Branches
Tags
No related merge requests found
Showing
with 762 additions and 132 deletions
......@@ -9,14 +9,44 @@ and this project adheres to [Semantic Versioning](https://semver.org/spec/v2.0.0
### Added ###
* Added a `_get_head_iversion` for non-api usage.
### Changed ###
* Added a `versioned` flag to the following procedures:
* `applyBackReference`
* `applyIDFilter`
* `applyPOV`
* `applyRefPOV`
* `makeStmt`
* `calcComplementUnion`
* `calcDifference`
* `calcIntersection`
* `finishSubProperty`
* `getChildren`
* `initEmptyTargetSet`
* `initDisjunctionFilter`
* `initEntity`
* `initQuery`
* `createTmpTable`
* Added a `direct` column to `archive_isa` table
### Deprecated ###
### Removed ###
* unused procedures:
* `initNegationFilter`
* `initConjunctionFilter`
* `finishNegationFilter`
### Fixed ###
* Semi-fix in `retrieveEntityParents`. The old implementation was buggy and
would return no parent name or even a wrong one for old entity versions in
some cases. The semi-fix will allways return the current name of the parent
(even if this is historically not always correct). A real fix awaits the
implementation of versioned isa-relations which is already planned.
* Bug in `retrieveOverrides` function where selecting the datatype of an old
version resultet in an error. See corresponding test in `caosdb-pyinttest`
`tests/test_versioning.py::test_datatype_without_name`
......
......@@ -73,5 +73,11 @@ with the then current version of the stored entities.
## Unit tests
* We use [MyTAP-1.0](https://hepabolu.github.io/mytap/) for unit tests.
* Requirements:
* mysqladmin
* mysqldump
* mysql client program
* Tests are in `tests/test_*.sql`.
* Run `make test`.
* Alternatively, to run the tests in a containerized MariaDB instance, run `make test-docker`,
followed by `make test-docker-stop`.
......@@ -101,7 +101,10 @@ There are a few extra tables for implementing versioning. Also there is a speci
`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 ###
The `_iversion` is an incremental version counter, starting implicitly at 1. Previous versions of
entities are stored, along with their `_iversion`, in the `archive_*` tables.
### `transactions` ###
Replacement for `transaction_log`, holds ID, user and time of transaction:
......@@ -123,15 +126,15 @@ Versioning info for entities:
- `_ipparent` :: Primary parent ID (internal) for this version, i.e. predecessor
- `srid` :: Server request / transaction ID which created this version
### `archive_foo_data` ###
### `archive_footable` ###
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`.
Older (i.e. not current) data, from previous versions of an entity which were stored in `footable`.
- `domain_id` :: Same as in `footable`.
- `entity_id` :: Same as in `footable`.
- `property_id` :: Same as in `footable`.
- `value` :: The value at the given version.
- `status` :: The value at the given version.
- `pidx` :: Same as in `foo_data`.
- `pidx` :: Same as in `footable`.
- `_iversion` :: Version index of this version.
- ... :: Data type specific columns may also be there.
......
#!/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
#
# Update mysql schema to version v4.0.0-rc1
NEW_VERSION="v4.0.0-rc1"
OLD_VERSION="v3.0.0-rc2"
if [ -z "$UTILSPATH" ]; then
UTILSPATH="../utils"
fi
. $UTILSPATH/patch_header.sh $*
check_version $OLD_VERSION
# * Add a `direct` column to `archive_isa` table
# * Remove unused procedures:
# * `initNegationFilter`
# * `initConjunctionFilter`
# * `finishNegationFilter`
mysql_execute_file $PATCH_DIR/update_archive_isa.sql
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/>.
*/
-- remove unused procedures
DROP PROCEDURE IF EXISTS db_2_0.initNegationFilter;
DROP PROCEDURE IF EXISTS db_2_0.initConjunctionFilter;
DROP PROCEDURE IF EXISTS db_2_0.finishNegationFilter;
ALTER TABLE archive_isa
ADD COLUMN `direct` BOOLEAN DEFAULT TRUE;
......@@ -50,12 +50,11 @@ BEGIN
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
-- move to archive_isa before deleting
INSERT IGNORE INTO archive_isa (child, child_iversion, parent, direct)
SELECT e.child, IVersion AS child_iversion, e.parent, rpath = EntityID
FROM isa_cache AS e
WHERE e.child = EntityID
AND e.rpath = CAST(EntityID AS CHAR);
WHERE e.child = EntityID;
END IF;
DELETE FROM isa_cache
......
......@@ -226,6 +226,38 @@ BEGIN
END;
//
DROP FUNCTION IF EXISTS db_2_0._get_head_iversion //
/**
* Get the _iversion number of the HEAD of an entity.
*
* Parameters
* ----------
* EntityID
* The entity id.
*
* Returns
* -------
* The _iversion of the HEAD.
*/
CREATE FUNCTION db_2_0._get_head_iversion(
EntityID INT UNSIGNED)
RETURNS INT UNSIGNED
READS SQL DATA
BEGIN
-- This implementation assumes that the history is linear and the highest
-- _iversion number is always the head. 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._iversion
FROM entity_version AS e
WHERE e.entity_id = EntityID
ORDER BY e._iversion DESC
LIMIT 1
);
END;
DROP FUNCTION IF EXISTS db_2_0.get_head_relative //
......
......@@ -4,6 +4,9 @@
*
* 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>
* Copyright (C) 2020 Daniel Hornung <d.hornung@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,7 +27,43 @@
DROP PROCEDURE IF EXISTS db_2_0.applyBackReference;
DELIMITER //
CREATE PROCEDURE db_2_0.applyBackReference(in sourceSet VARCHAR(255), targetSet VARCHAR(255), in propertiesTable VARCHAR(255), in entitiesTable VARCHAR(255), in subQuery BOOLEAN)
/**
* Process a set of entities, keeping those which are referenced in a specific way.
*
* This procedure filters a source table and writes the result into a target table. If
* the target table is not given, all non-matching entries are deleted from the source table
* instead.
*
* Candidate entities are allowed to pass if there is an entity from the entities table which
* references the candidate as one of the properties in the properties table.
*
* Parameters
* ----------
* sourceSet : table
* The name of the table which shall be filtered, must have column `id`.
*
* targetSet : table
* The name of the result table, must have column `id`.
*
* propertiesTable : table
* References as Properties in this table are counted.
*
* entitiesTable : table
* References by Entities in this table are counted.
*
* subQuery : boolean
* Create a temporary target table and select as `list`, instead of using the given targetSet. The
* `versioned` parameter has no effect in this case.
*
* versioned : boolean
* If True, if a reference is versioned (references to specific versions of entities), the target
* candidate's version must match. Therefore, the sourceSet and targetSet must have a `_iversion`
* column as well (unless sourceSet is the `entities` table).
*
*/
CREATE PROCEDURE db_2_0.applyBackReference(in sourceSet VARCHAR(255), targetSet VARCHAR(255),
in propertiesTable VARCHAR(255), in entitiesTable VARCHAR(255), in subQuery BOOLEAN,
in versioned BOOLEAN)
BEGIN
DECLARE newTableName VARCHAR(255) DEFAULT NULL;
......@@ -38,7 +77,23 @@ BEGIN
EXECUTE createBackRefSubQueryTable;
DEALLOCATE PREPARE createBackRefSubQueryTable;
SET @backRefSubResultSetStmtStr = CONCAT('INSERT IGNORE INTO `',newTableName,'` (id,entity_id) SELECT entity_id AS id, value AS entity_id FROM `reference_data` AS data WHERE EXISTS (SELECT 1 FROM `',sourceSet,'` AS source WHERE source.id=data.value LIMIT 1)', IF(propertiesTable IS NULL,'',CONCAT(' AND EXISTS (SELECT 1 FROM `',propertiesTable,'` AS p WHERE p.id=data.property_id LIMIT 1)')), IF(entitiesTable IS NULL,'',CONCAT(' AND EXISTS (SELECT 1 FROM `',entitiesTable,'` AS e WHERE e.id=data.entity_id LIMIT 1)')));
SET @backRefSubResultSetStmtStr = CONCAT('INSERT IGNORE INTO `',
newTableName,
'` (id,entity_id) SELECT entity_id AS id, value AS entity_id FROM `reference_data` AS data ',
'WHERE EXISTS (SELECT 1 FROM `',
sourceSet,
'` AS source WHERE source.id=data.value LIMIT 1)',
IF(propertiesTable IS NULL,
'',
CONCAT(' AND EXISTS (SELECT 1 FROM `',
propertiesTable,
'` AS p WHERE p.id=data.property_id LIMIT 1)')),
IF(entitiesTable IS NULL,
'',
CONCAT(' AND EXISTS (SELECT 1 FROM `',
entitiesTable,
'` AS e WHERE e.id=data.entity_id LIMIT 1)'))
);
PREPARE backRefSubResultSetStmt FROM @backRefSubResultSetStmtStr;
EXECUTE backRefSubResultSetStmt;
......@@ -46,10 +101,124 @@ BEGIN
SELECT newTableName as list;
ELSE
IF versioned THEN
IF sourceSet = "entities" THEN
-- Find any referenced entity, current or archived
SET @stmtBackRefStr = CONCAT('INSERT IGNORE INTO `',
targetSet,
'` (id, _iversion) SELECT source.id, _get_head_iversion(source.id)',
-- current entities
' FROM entities AS source WHERE EXISTS (',
'SELECT 1 FROM `reference_data` AS data WHERE data.value=source.id AND (',
'data.value_iversion IS NULL OR data.value_iversion=_get_head_iversion(source.id))',
IF(entitiesTable IS NULL,
'',
CONCAT(' AND EXISTS (SELECT 1 FROM `',
entitiesTable,
'` AS e WHERE e.id=data.entity_id LIMIT 1)')),
IF(propertiesTable IS NULL,
'',
CONCAT(' AND EXISTS (SELECT 1 FROM `',
propertiesTable,
'` AS p WHERE p.id=data.property_id LIMIT 1)')),
') UNION ALL ',
-- and archived entities
'SELECT source.id, source._iversion FROM archive_entities AS source WHERE EXISTS (',
'SELECT 1 FROM `reference_data` AS data WHERE data.value=source.id AND ',
'(data.value_iversion IS NULL OR data.value_iversion=source._iversion)',
IF(entitiesTable IS NULL,
'',
CONCAT(' AND EXISTS (SELECT 1 FROM `',
entitiesTable,
'` AS e WHERE e.id=data.entity_id LIMIT 1)')),
IF(propertiesTable IS NULL,
'',
CONCAT(' AND EXISTS (SELECT 1 FROM `',
propertiesTable,
'` AS p WHERE p.id=data.property_id LIMIT 1)')),
')');
ELSEIF targetSet IS NULL OR sourceSet = targetSet THEN
SET @stmtBackRefStr = CONCAT('DELETE FROM `',
sourceSet,
'` WHERE NOT EXISTS (SELECT 1 FROM `reference_data` AS data WHERE data.value=`',
sourceSet,
'`.`id` AND ( data.value_iversion IS NULL OR data.value_iversion=`',
sourceSet,
'`._iversion)',
IF(entitiesTable IS NULL,
'',
CONCAT(' AND EXISTS (SELECT 1 FROM `',
entitiesTable,
'` AS e WHERE e.id=data.entity_id LIMIT 1)')),
IF(propertiesTable IS NULL,
'',
CONCAT(' AND EXISTS (SELECT 1 FROM `',
propertiesTable,
'` AS p WHERE p.id=data.property_id LIMIT 1)')),
')');
ELSE
SET @stmtBackRefStr = CONCAT('INSERT IGNORE INTO `',
targetSet,
'` (id, _iversion) SELECT source.id, source._iversion FROM `',
sourceSet,
'` AS source WHERE EXISTS (',
'SELECT 1 FROM `reference_data` AS data WHERE data.value=source.id AND',
' (data.value_iversion IS NULL OR data.value_iversion=source._iversion)',
IF(entitiesTable IS NULL,
'',
CONCAT(' AND EXISTS (SELECT 1 FROM `',
entitiesTable,
'` AS e WHERE e.id=data.entity_id LIMIT 1)')),
IF(propertiesTable IS NULL,
'',
CONCAT(' AND EXISTS (SELECT 1 FROM `',
propertiesTable,
'` AS p WHERE p.id=data.property_id LIMIT 1)')),
')');
END IF;
ELSE
-- unversioned queries
IF targetSet IS NULL OR sourceSet = targetSet THEN
SET @stmtBackRefStr = CONCAT('DELETE FROM `', sourceSet, '` WHERE NOT EXISTS (SELECT 1 FROM `reference_data` AS data WHERE data.value=`', sourceSet, '`.`id`', IF(entitiesTable IS NULL, '', CONCAT(' AND EXISTS (SELECT 1 FROM `', entitiesTable, '` AS e WHERE e.id=data.entity_id LIMIT 1)')), IF(propertiesTable IS NULL, '', CONCAT(' AND EXISTS (SELECT 1 FROM `', propertiesTable, '` AS p WHERE p.id=data.property_id LIMIT 1)')), ')');
-- delete from sourceSet
SET @stmtBackRefStr = CONCAT('DELETE FROM `',
sourceSet,
'` WHERE NOT EXISTS (SELECT 1 FROM `reference_data` AS data WHERE data.value=`',
sourceSet,
'`.`id`',
IF(entitiesTable IS NULL,
'',
CONCAT('
AND EXISTS (SELECT 1 FROM `',
entitiesTable,
'` AS e WHERE e.id=data.entity_id LIMIT 1)')),
IF(propertiesTable IS NULL,
'',
CONCAT('
AND EXISTS (SELECT 1 FROM `',
propertiesTable,
'` AS p WHERE p.id=data.property_id LIMIT 1)')),
')');
ELSE
SET @stmtBackRefStr = CONCAT('INSERT IGNORE INTO `', targetSet, '` (id) SELECT id FROM `',sourceSet,'` AS source WHERE EXISTS (SELECT 1 FROM `reference_data` AS data WHERE data.value=source.id', IF(entitiesTable IS NULL, '', CONCAT(' AND EXISTS (SELECT 1 FROM `', entitiesTable, '` AS e WHERE e.id=data.entity_id LIMIT 1)')), IF(propertiesTable IS NULL, '', CONCAT(' AND EXISTS (SELECT 1 FROM `', propertiesTable, '` AS p WHERE p.id=data.property_id LIMIT 1)')), ')');
-- write to targetSet
SET @stmtBackRefStr = CONCAT('INSERT IGNORE INTO `',
targetSet,
'` (id) SELECT id FROM `',
sourceSet,
'` AS source WHERE EXISTS (SELECT 1 FROM `reference_data` AS data WHERE data.value=source.id',
IF(entitiesTable IS NULL,
'',
CONCAT(' AND EXISTS (SELECT 1 FROM `',
entitiesTable,
'` AS e WHERE e.id=data.entity_id LIMIT 1)')),
IF(propertiesTable IS NULL,
'',
CONCAT(' AND EXISTS (SELECT 1 FROM `',
propertiesTable,
'` AS p WHERE p.id=data.property_id LIMIT 1)')),
')');
END IF;
END IF;
PREPARE stmtBackRef FROM @stmtBackRefStr;
......
......@@ -25,14 +25,32 @@ DROP PROCEDURE IF EXISTS db_2_0.applyIDFilter;
DELIMITER //
CREATE PROCEDURE db_2_0.applyIDFilter(in sourceSet VARCHAR(255), in targetSet VARCHAR(255), in o CHAR(2), in vInt BIGINT, in agg CHAR(3))
/**
* Filter the sourceSet into targetSet by ID.
*
* This can be done by operator-value tests or by aggregate functions.
*
* The `versioned` flag currently only has the effect that an `_iversion` column is also copied to
* the target.
*/
CREATE PROCEDURE db_2_0.applyIDFilter(in sourceSet VARCHAR(255), in targetSet VARCHAR(255),
in o CHAR(2), in vInt BIGINT, in agg CHAR(3), in versioned BOOLEAN)
IDFILTER_LABEL: BEGIN
DECLARE data VARCHAR(20000) DEFAULT NULL;
DECLARE aggVal VARCHAR(255) DEFAULT NULL;
#-- get aggVal if possible
IF agg IS NOT NULL THEN
SET @stmtIDAggValStr = CONCAT("SELECT ", agg, "(id) INTO @sAggVal FROM `", sourceSet, "`");
IF versioned THEN
-- TODO versioned queries
SELECT 1 FROM id_agg_with_versioning_not_implemented;
END IF;
SET @stmtIDAggValStr = CONCAT(
"SELECT ",
agg,
"(id) INTO @sAggVal FROM `",
sourceSet,
"`");
PREPARE stmtIDAggVal FROM @stmtIDAggValStr;
EXECUTE stmtIDAggVal;
DEALLOCATE PREPARE stmtIDAggVal;
......@@ -41,9 +59,65 @@ END IF;
#-- generate stmt string
IF targetSet IS NULL OR targetSet = sourceSet THEN
SET data = CONCAT("DELETE FROM `",sourceSet,"` WHERE ",IF(o IS NULL OR vInt IS NULL,"1=1",CONCAT("NOT id",o,vInt)),IF(aggVal IS NULL, "", CONCAT(" AND id!=",aggVal)));
SET data = CONCAT(
"DELETE FROM `",
sourceSet,
"` WHERE ",
IF(o IS NULL OR vInt IS NULL,
"1=1",
CONCAT("NOT id",
o,
vInt)),
IF(aggVal IS NULL,
"",
CONCAT(" AND id!=",
aggVal)));
ELSEIF versioned AND sourceSet = "entities" THEN
-- ################# VERSIONING #####################
SET data = CONCAT(
"INSERT IGNORE INTO `",
targetSet,
'` (id, _iversion) SELECT id, _get_head_iversion(id) FROM `entities` WHERE ',
IF(o IS NULL OR vInt IS NULL,
"1=1",
CONCAT("id",
o,
vInt)),
IF(aggVal IS NULL,
"",
CONCAT(" AND id=",
aggVal)),
' UNION SELECT id, _iversion FROM `archive_entities` WHERE ',
IF(o IS NULL OR vInt IS NULL,
"1=1",
CONCAT("id",
o,
vInt)),
IF(aggVal IS NULL,
"",
CONCAT(" AND id=",
aggVal)));
-- ##################################################
ELSE
SET data = CONCAT("INSERT IGNORE INTO `",targetSet,"` SELECT data.id as id FROM `",sourceSet,"` AS data WHERE ",IF(o IS NULL OR vInt IS NULL,"1=1",CONCAT("data.id",o,vInt)),IF(aggVal IS NULL, "", CONCAT(" AND data.id=", aggVal)));
SET data = CONCAT(
"INSERT IGNORE INTO `",
targetSet,
IF(versioned,
'` (id, _iversion) SELECT data.id, data._iversion FROM `',
'` (id) SELECT data.id FROM `'),
sourceSet,
"` AS data WHERE ",
IF(o IS NULL OR vInt IS NULL,
"1=1",
CONCAT("data.id",
o,
vInt)),
IF(aggVal IS NULL,
"",
CONCAT(" AND data.id=",
aggVal)));
END IF;
Set @stmtIDFilterStr = data;
......
This diff is collapsed.
......@@ -23,10 +23,24 @@
DROP PROCEDURE IF EXISTS db_2_0.applyRefPOV;
DELIMITER //
CREATE PROCEDURE db_2_0.applyRefPOV(in sourceSet VARCHAR(255), in targetSet VARCHAR(255), in properties VARCHAR(255), in refs VARCHAR(255))
CREATE PROCEDURE db_2_0.applyRefPOV(in sourceSet VARCHAR(255), in targetSet VARCHAR(255),
in properties VARCHAR(255), in refs VARCHAR(255),
in versioned BOOLEAN)
BEGIN
DECLARE data VARCHAR(20000) DEFAULT CONCAT('(SELECT domain_id, entity_id, property_id FROM `reference_data` AS subdata WHERE EXISTS (SELECT 1 FROM `', refs, '` AS refs WHERE subdata.value=refs.id LIMIT 1))');
SET @stmtRefPOVStr = makeStmt(sourceSet,targetSet,data,properties);
DECLARE data VARCHAR(20000) DEFAULT CONCAT(
'(SELECT domain_id, entity_id, property_id FROM `reference_data` AS subdata ',
'WHERE EXISTS (SELECT 1 FROM `', refs, '` AS refs WHERE subdata.value=refs.id LIMIT 1))');
IF versioned THEN
SET data = CONCAT(
'(SELECT domain_id, entity_id, _get_head_iversion(entity_id) AS _iversion, property_id ',
'FROM `reference_data` AS subdata WHERE EXISTS (',
'SELECT 1 FROM `', refs, '` AS refs WHERE subdata.value=refs.id LIMIT 1) ',
'UNION ALL SELECT domain_id, entity_id, _iversion, property_id ',
'FROM `archive_reference_data` AS subdata WHERE EXISTS (',
'SELECT 1 FROM `', refs, '` AS refs WHERE subdata.value=refs.id LIMIT 1))');
END IF;
SET @stmtRefPOVStr = makeStmt(sourceSet,targetSet,data,properties, versioned);
PREPARE stmt4 FROM @stmtRefPOVStr;
EXECUTE stmt4;
......
......@@ -39,7 +39,7 @@ BEGIN
')'
);
SET @stmtTransactionStr = makeStmt(sourceSet,targetSet,data,NULL);
SET @stmtTransactionStr = makeStmt(sourceSet, targetSet, data, NULL, FALSE);
PREPARE stmtTransactionFilter from @stmtTransactionStr;
IF userName IS NOT NULL THEN
SET @userName = userName;
......
......@@ -23,11 +23,29 @@
DROP PROCEDURE IF EXISTS db_2_0.calcComplementUnion;
-- Apparently this code is not used anymore
DELIMITER //
CREATE PROCEDURE db_2_0.calcComplementUnion(in targetSet VARCHAR(255), in subResultSet VARCHAR(255), in universe VARCHAR(255))
CREATE PROCEDURE db_2_0.calcComplementUnion(in targetSet VARCHAR(255), in subResultSet VARCHAR(255), in universe VARCHAR(255), in versioned BOOLEAN)
BEGIN
IF versioned AND universe = "entities" THEN
SET @stmtComplementUnionStr = CONCAT(
'INSERT IGNORE INTO `', targetSet,
'` SELECT e.id, _get_head_iversion(e.id) FROM entities as e WHERE NOT EXISTS ( SELECT 1 FROM `',
subResultSet,
'` AS diff WHERE diff.id=e.id AND diff._iversion = _get_head_iversion(e.id)) UNION ALL SELECT e.id, e._iversion FROM archive_entities AS e WHERE NOT EXISTS ( SELECT 1 FROM `',
subResultSet,
'` as diff WHERE e.id = diff.id AND e._iversion = diff._iversion)');
ELSEIF versioned THEN
SET @stmtComplementUnionStr = CONCAT(
'INSERT IGNORE INTO `', targetSet,
'` SELECT id FROM `',universe,
'` AS universe WHERE NOT EXISTS ( SELECT 1 FROM `',
subResultSet,'`
AS diff WHERE diff.id=universe.id AND diff._iversion = universe.id_version)');
ELSE
SET @stmtComplementUnionStr = CONCAT('INSERT IGNORE INTO `', targetSet, '` SELECT id FROM `',universe, '` AS universe WHERE NOT EXISTS ( SELECT 1 FROM `', subResultSet,'` AS diff WHERE diff.id=universe.id)');
END IF;
PREPARE stmtComplementUnion FROM @stmtComplementUnionStr;
EXECUTE stmtComplementUnion;
DEALLOCATE PREPARE stmtComplementUnion;
......
......@@ -27,9 +27,16 @@
DROP PROCEDURE IF EXISTS db_2_0.calcDifference;
DELIMITER //
CREATE PROCEDURE db_2_0.calcDifference(in resultSetTable VARCHAR(255), in diff VARCHAR(255))
/**
* Delete rows from `resultSetTable` which have a matching ID (an version) in `diff`.
*/
CREATE PROCEDURE db_2_0.calcDifference(in resultSetTable VARCHAR(255), in diff VARCHAR(255), in versioned BOOLEAN)
BEGIN
IF versioned THEN
SET @diffStmtStr = CONCAT('DELETE FROM `', resultSetTable, '` WHERE EXISTS ( SELECT 1 FROM `', diff,'` AS diff WHERE diff.id=`',resultSetTable,'`.`id` AND diff._iversion=`', resultSetTable, '`.`_iversion`)');
ELSE
SET @diffStmtStr = CONCAT('DELETE FROM `', resultSetTable, '` WHERE EXISTS ( SELECT 1 FROM `', diff,'` AS diff WHERE diff.id=`',resultSetTable,'`.`id`)');
END IF;
PREPARE diffStmt FROM @diffStmtStr;
EXECUTE diffStmt;
DEALLOCATE PREPARE diffStmt;
......
......@@ -25,9 +25,24 @@
DROP PROCEDURE IF EXISTS db_2_0.calcIntersection;
DELIMITER //
CREATE PROCEDURE db_2_0.calcIntersection(in resultSetTable VARCHAR(255), in intersectWith VARCHAR(255))
/**
* Drop rows in `resultSetTable` which do not have a matching ID (and version) in `intersectWith`.
*/
CREATE PROCEDURE db_2_0.calcIntersection(in resultSetTable VARCHAR(255), in intersectWith VARCHAR(255), in versioned BOOLEAN)
BEGIN
IF versioned THEN
SET @diffStmtStr = CONCAT('DELETE FROM `',
resultSetTable,
'` WHERE NOT EXISTS ( SELECT 1 FROM `',
intersectWith,
'` AS diff WHERE diff.id=`',
resultSetTable,
'`.`id` AND diff._iversion=`',
resultSetTable,
'`.`_iversion`)');
ELSE
SET @diffStmtStr = CONCAT('DELETE FROM `', resultSetTable, '` WHERE NOT EXISTS ( SELECT 1 FROM `', intersectWith,'` AS diff WHERE diff.id=`',resultSetTable,'`.`id`)');
END IF;
PREPARE diffStmt FROM @diffStmtStr;
EXECUTE diffStmt;
......
......@@ -26,9 +26,12 @@
DROP PROCEDURE IF EXISTS db_2_0.calcUnion;
DELIMITER //
/**
* Add the rows from `sourceSet` to `targetSet`.
*/
CREATE PROCEDURE db_2_0.calcUnion(in targetSet VARCHAR(255), in sourceSet VARCHAR(255))
BEGIN
SET @diffStmtStr = CONCAT('INSERT IGNORE INTO `', targetSet, '` (id) SELECT id FROM `',sourceSet,'`');
SET @diffStmtStr = CONCAT('INSERT IGNORE INTO `', targetSet, '` SELECT * FROM `',sourceSet,'`');
PREPARE diffStmt FROM @diffStmtStr;
EXECUTE diffStmt;
DEALLOCATE PREPARE diffStmt;
......
......@@ -27,11 +27,16 @@
DROP PROCEDURE IF EXISTS db_2_0.cleanUpQuery;
DELIMITER //
/**
* Drop temporary tables and warnings, existing warnings are returned in the result set.
*/
CREATE PROCEDURE db_2_0.cleanUpQuery()
BEGIN
CREATE TEMPORARY TABLE IF NOT EXISTS warnings (warning TEXT NOT NULL);
SELECT * from warnings;
SET @pstmtstr = CONCAT('DROP TEMPORARY TABLE IF EXISTS `warnings`', IF(@tempTableList IS NULL, '', CONCAT(',',@tempTableList)));
SET @pstmtstr = CONCAT('DROP TEMPORARY TABLE IF EXISTS `warnings`',
IF(@tempTableList IS NULL, '', CONCAT(',',@tempTableList)));
PREPARE pstmt FROM @pstmtstr;
EXECUTE pstmt;
......
......@@ -27,7 +27,10 @@ DELIMITER //
CREATE PROCEDURE db_2_0.registerTempTableName(out newTableName VARCHAR(255))
BEGIN
SET newTableName = md5(CONCAT(RAND(),CURRENT_TIMESTAMP()));
SET @tempTableList = IF(@tempTableList IS NULL, CONCAT('`',newTableName,'`'), CONCAT(@tempTableList, ',`', newTableName, '`'));
SET @tempTableList = IF(@tempTableList IS NULL,
CONCAT('`',newTableName,'`'),
CONCAT(@tempTableList, ',`', newTableName, '`')
);
END;
//
DELIMITER ;
......@@ -35,11 +38,22 @@ DELIMITER ;
DROP PROCEDURE IF EXISTS db_2_0.createTmpTable;
DELIMITER //
CREATE PROCEDURE db_2_0.createTmpTable(out newTableName VARCHAR(255))
/**
* If not versioned: Creates a temporary table for query results with only a single `id` column.
*
* If versioned: Creates a temporary table for query results with an `id`
* column and an `_iversion` column.
*/
CREATE PROCEDURE db_2_0.createTmpTable(out newTableName VARCHAR(255), in versioned BOOLEAN)
BEGIN
call registerTempTableName(newTableName);
IF versioned THEN
SET @createTableStmtStr = CONCAT('CREATE TEMPORARY TABLE `', newTableName,
'` ( id INT UNSIGNED, _iversion INT UNSIGNED, PRIMARY KEY (id, _iversion))' );
ELSE
SET @createTableStmtStr = CONCAT('CREATE TEMPORARY TABLE `', newTableName,'` ( id INT UNSIGNED PRIMARY KEY)' );
END IF;
PREPARE createTableStmt FROM @createTableStmtStr;
EXECUTE createTableStmt;
......@@ -51,13 +65,21 @@ DELIMITER ;
/**
* Creates a temporary table for intermediate query results with three columns
* id - for entity ids (e.g. property ids or reference values)
* id2 - for entity ids (usually those entities which have the other id as property or value)
* domain - for domain ids
*/
DROP PROCEDURE IF EXISTS db_2_0.createTmpTable2;
DELIMITER //
CREATE PROCEDURE db_2_0.createTmpTable2(out newTableName VARCHAR(255))
BEGIN
call registerTempTableName(newTableName);
SET @createTableStmtStr = CONCAT('CREATE TEMPORARY TABLE `', newTableName,'` ( id INT UNSIGNED, id2 INT UNSIGNED, domain INT UNSIGNED, CONSTRAINT `', newTableName,'PK` PRIMARY KEY (id,id2,domain) )' );
SET @createTableStmtStr = CONCAT('CREATE TEMPORARY TABLE `', newTableName,
'` ( id INT UNSIGNED, id2 INT UNSIGNED, domain INT UNSIGNED, CONSTRAINT `',
newTableName,'PK` PRIMARY KEY (id,id2,domain) )' );
PREPARE createTableStmt FROM @createTableStmtStr;
EXECUTE createTableStmt;
......
......@@ -24,10 +24,11 @@
DROP PROCEDURE IF EXISTS db_2_0.finishSubProperty;
DELIMITER //
CREATE PROCEDURE db_2_0.finishSubProperty(in sourceSet VARCHAR(255),in targetSet VARCHAR(255), in list VARCHAR(255))
CREATE PROCEDURE db_2_0.finishSubProperty(in sourceSet VARCHAR(255),in targetSet VARCHAR(255),
in list VARCHAR(255), in versioned BOOLEAN)
BEGIN
DECLARE data VARCHAR(20000) DEFAULT CONCAT('`',list,'`');
SET @finishSubPropertyStmtStr = makeStmt(sourceSet, targetSet, data, NULL);
SET @finishSubPropertyStmtStr = makeStmt(sourceSet, targetSet, data, NULL, versioned);
PREPARE finishSubPropertyStmt FROM @finishSubPropertyStmtStr;
EXECUTE finishSubPropertyStmt;
......
......@@ -23,20 +23,57 @@
Drop Procedure if exists db_2_0.getChildren;
Delimiter //
Create Procedure db_2_0.getChildren(in tableName varchar(255))
/**
* Find and return all children of the IDs given in `tableName`.
*
* If the `versioned` parameter is `TRUE`, also all archived (non-HEAD) children are added.
*/
Create Procedure db_2_0.getChildren(in tableName varchar(255), in versioned BOOLEAN)
BEGIN
DECLARE found_children INT UNSIGNED DEFAULT 0;
DROP TEMPORARY TABLE IF EXISTS dependTemp;
CREATE TEMPORARY TABLE dependTemp (id INT UNSIGNED, _iversion INT UNSIGNED, PRIMARY KEY(id, _iversion));
CREATE TEMPORARY TABLE dependTemp (id INT UNSIGNED PRIMARY KEY);
SET @initDepend = CONCAT(
'INSERT IGNORE INTO dependTemp (id, _iversion) SELECT i.child, ',
IF(versioned,
'_get_head_iversion(i.child)',
'0'),
' FROM isa_cache AS i INNER JOIN `',
tableName,
'` AS t ON (i.parent=t.id);');
PREPARE initDependStmt FROM @initDepend;
EXECUTE initDependStmt;
SET found_children = found_children + ROW_COUNT();
-- ################# VERSIONING #####################
SET @initDepend = CONCAT('INSERT IGNORE INTO dependTemp (id) SELECT i.child FROM isa_cache AS i INNER JOIN `', tableName, '` AS t ON (i.parent=t.id);');
IF versioned IS TRUE THEN
SET @initDepend = CONCAT(
'INSERT IGNORE INTO dependTemp (id, _iversion) ',
'SELECT i.child, i.child_iversion FROM archive_isa AS i INNER JOIN `',
tableName,
'` AS t ON (i.parent=t.id);');
PREPARE initDependStmt FROM @initDepend;
EXECUTE initDependStmt;
IF ROW_COUNT() != 0 THEN
SET @transfer = CONCAT('INSERT IGNORE INTO `', tableName, '` (id) SELECT id FROM dependTemp');
SET found_children = found_children + ROW_COUNT();
END IF;
-- ##################################################
IF found_children != 0 THEN
SET @transfer = CONCAT(
'INSERT IGNORE INTO `',
tableName,
IF(versioned,
'` (id, _iversion) SELECT id, _iversion FROM dependTemp',
'` (id) SELECT id FROM dependTemp'));
PREPARE transferstmt FROM @transfer;
EXECUTE transferstmt;
DEALLOCATE PREPARE transferstmt;
......@@ -44,7 +81,6 @@ BEGIN
DEALLOCATE PREPARE initDependStmt;
DROP TEMPORARY TABLE dependTemp;
END;
//
......
0% Loading or .
You are about to add 0 people to the discussion. Proceed with caution.
Please register or to comment