Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

SQL schema cleanup #6492

Merged
merged 6 commits into from
Sep 27, 2022
Merged
Show file tree
Hide file tree
Changes from 5 commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
1 change: 1 addition & 0 deletions MIGRATIONS.unreleased.md
Original file line number Diff line number Diff line change
Expand Up @@ -13,3 +13,4 @@ User-facing changes are documented in the [changelog](CHANGELOG.released.md).
### Postgres Evolutions:
- [088-shortlinks.sql](conf/evolutions/088-shortlinks.sql)
- [089-voxelytics.sql](conf/evolutions/089-voxelytics.sql)
- [090-cleanup.sql](conf/evolutions/090-cleanup.sql)
56 changes: 56 additions & 0 deletions conf/evolutions/090-cleanup.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,56 @@
BEGIN transaction;

-- make datastore reference fields VARCHAR from CHAR, remove whitespace

DROP VIEW webknossos.jobs_;
ALTER TABLE webknossos.jobs DROP CONSTRAINT dataStore_ref;
ALTER TABLE webknossos.jobs RENAME COLUMN _dataStore to _dataStoreOLD;
ALTER TABLE webknossos.jobs ADD COLUMN _dataStore VARCHAR(256) NOT NULL;
UPDATE webknossos.jobs SET _dataStore = TRIM(_dataStoreOLD);
ALTER TABLE webknossos.jobs DROP COLUMN _dataStoreOLD;
ALTER TABLE webknossos.jobs ADD CONSTRAINT dataStore_ref FOREIGN KEY(_dataStore) REFERENCES webknossos.dataStores(name) DEFERRABLE;
CREATE VIEW webknossos.jobs_ AS SELECT * FROM webknossos.jobs WHERE NOT isDeleted;

DROP VIEW webknossos.dataSets_;
ALTER TABLE webknossos.dataSets DROP CONSTRAINT dataStore_ref;
ALTER TABLE webknossos.dataSets RENAME COLUMN _dataStore to _dataStoreOLD;
ALTER TABLE webknossos.dataSets ADD COLUMN _dataStore VARCHAR(256) NOT NULL;
UPDATE webknossos.dataSets SET _dataStore = TRIM(_dataStoreOLD);
ALTER TABLE webknossos.dataSets DROP COLUMN _dataStoreOLD;
ALTER TABLE webknossos.dataSets ADD CONSTRAINT dataStore_ref FOREIGN KEY(_dataStore) REFERENCES webknossos.dataStores(name) DEFERRABLE;
CREATE VIEW webknossos.dataSets_ AS SELECT * FROM webknossos.dataSets WHERE NOT isDeleted;

DROP VIEW webknossos.workers_;
ALTER TABLE webknossos.workers RENAME COLUMN _dataStore to _dataStoreOLD;
ALTER TABLE webknossos.workers ADD COLUMN _dataStore VARCHAR(256) NOT NULL;
UPDATE webknossos.workers SET _dataStore = TRIM(_dataStoreOLD);
ALTER TABLE webknossos.workers DROP COLUMN _dataStoreOLD;
ALTER TABLE webknossos.workers ADD CONSTRAINT dataStore_ref FOREIGN KEY(_dataStore) REFERENCES webknossos.dataStores(name) DEFERRABLE;
CREATE VIEW webknossos.workers_ AS SELECT * FROM webknossos.workers WHERE NOT isDeleted;

-- drop objectid defaults

ALTER TABLE webknossos.annotations ALTER COLUMN _id DROP DEFAULT;
ALTER TABLE webknossos.meshes ALTER COLUMN _id DROP DEFAULT;
ALTER TABLE webknossos.publications ALTER COLUMN _id DROP DEFAULT;
ALTER TABLE webknossos.dataSets ALTER COLUMN _id DROP DEFAULT;
ALTER TABLE webknossos.projects ALTER COLUMN _id DROP DEFAULT;
ALTER TABLE webknossos.scripts ALTER COLUMN _id DROP DEFAULT;
ALTER TABLE webknossos.taskTypes ALTER COLUMN _id DROP DEFAULT;
ALTER TABLE webknossos.tasks ALTER COLUMN _id DROP DEFAULT;
ALTER TABLE webknossos.teams ALTER COLUMN _id DROP DEFAULT;
ALTER TABLE webknossos.timespans ALTER COLUMN _id DROP DEFAULT;
ALTER TABLE webknossos.organizations ALTER COLUMN _id DROP DEFAULT;
ALTER TABLE webknossos.users ALTER COLUMN _id DROP DEFAULT;
ALTER TABLE webknossos.multiUsers ALTER COLUMN _id DROP DEFAULT;
ALTER TABLE webknossos.tokens ALTER COLUMN _id DROP DEFAULT;
ALTER TABLE webknossos.workers ALTER COLUMN _id DROP DEFAULT;
ALTER TABLE webknossos.jobs ALTER COLUMN _id DROP DEFAULT;
ALTER TABLE webknossos.invites ALTER COLUMN _id DROP DEFAULT;
ALTER TABLE webknossos.annotation_privateLinks ALTER COLUMN _id DROP DEFAULT;
ALTER TABLE webknossos.shortLinks ALTER COLUMN _id DROP DEFAULT;

UPDATE webknossos.releaseInformation SET schemaVersion = 90;

COMMIT;

58 changes: 58 additions & 0 deletions conf/evolutions/reversions/090-cleanup.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,58 @@
BEGIN transaction;

-- make datastore reference fields CHAR from VARCHAR

DROP VIEW webknossos.jobs_;
ALTER TABLE webknossos.jobs DROP CONSTRAINT dataStore_ref;
ALTER TABLE webknossos.jobs RENAME COLUMN _dataStore to _dataStoreOLD;
ALTER TABLE webknossos.jobs ADD COLUMN _dataStore CHAR(256) NOT NULL;
UPDATE webknossos.jobs SET _dataStore = _dataStoreOLD;
ALTER TABLE webknossos.jobs DROP COLUMN _dataStoreOLD;
ALTER TABLE webknossos.jobs ADD CONSTRAINT dataStore_ref FOREIGN KEY(_dataStore) REFERENCES webknossos.dataStores(name) DEFERRABLE;
CREATE VIEW webknossos.jobs_ AS SELECT * FROM webknossos.jobs WHERE NOT isDeleted;

DROP VIEW webknossos.dataSets_;
ALTER TABLE webknossos.dataSets DROP CONSTRAINT dataStore_ref;
ALTER TABLE webknossos.dataSets RENAME COLUMN _dataStore to _dataStoreOLD;
ALTER TABLE webknossos.dataSets ADD COLUMN _dataStore CHAR(256) NOT NULL;
UPDATE webknossos.dataSets SET _dataStore = _dataStoreOLD;
ALTER TABLE webknossos.dataSets DROP COLUMN _dataStoreOLD;
ALTER TABLE webknossos.dataSets ADD CONSTRAINT dataStore_ref FOREIGN KEY(_dataStore) REFERENCES webknossos.dataStores(name) DEFERRABLE;
CREATE VIEW webknossos.dataSets_ AS SELECT * FROM webknossos.dataSets WHERE NOT isDeleted;

DROP VIEW webknossos.workers_;
ALTER TABLE webknossos.workers DROP CONSTRAINT dataStore_ref;
ALTER TABLE webknossos.workers RENAME COLUMN _dataStore to _dataStoreOLD;
ALTER TABLE webknossos.workers ADD COLUMN _dataStore CHAR(256) NOT NULL;
UPDATE webknossos.workers SET _dataStore = _dataStoreOLD;
ALTER TABLE webknossos.workers DROP COLUMN _dataStoreOLD;
ALTER TABLE webknossos.workers ADD CONSTRAINT dataStore_ref FOREIGN KEY(_dataStore) REFERENCES webknossos.dataStores(name) DEFERRABLE;
CREATE VIEW webknossos.workers_ AS SELECT * FROM webknossos.workers WHERE NOT isDeleted;

-- add objectid defaults

ALTER TABLE webknossos.annotations ALTER COLUMN _id SET DEFAULT '';
ALTER TABLE webknossos.meshes ALTER COLUMN _id SET DEFAULT '';
ALTER TABLE webknossos.meshes ALTER COLUMN _id SET NOT NULL;
ALTER TABLE webknossos.publications ALTER COLUMN _id SET DEFAULT '';
ALTER TABLE webknossos.dataSets ALTER COLUMN _id SET DEFAULT '';
ALTER TABLE webknossos.projects ALTER COLUMN _id SET DEFAULT '';
ALTER TABLE webknossos.scripts ALTER COLUMN _id SET DEFAULT '';
ALTER TABLE webknossos.taskTypes ALTER COLUMN _id SET DEFAULT '';
ALTER TABLE webknossos.tasks ALTER COLUMN _id SET DEFAULT '';
ALTER TABLE webknossos.teams ALTER COLUMN _id SET DEFAULT '';
ALTER TABLE webknossos.timespans ALTER COLUMN _id SET DEFAULT '';
ALTER TABLE webknossos.organizations ALTER COLUMN _id SET DEFAULT '';
ALTER TABLE webknossos.users ALTER COLUMN _id SET DEFAULT '';
ALTER TABLE webknossos.multiUsers ALTER COLUMN _id SET DEFAULT '';
ALTER TABLE webknossos.tokens ALTER COLUMN _id SET DEFAULT '';
ALTER TABLE webknossos.workers ALTER COLUMN _id SET DEFAULT '';
ALTER TABLE webknossos.jobs ALTER COLUMN _id SET DEFAULT '';
ALTER TABLE webknossos.invites ALTER COLUMN _id SET DEFAULT '';
ALTER TABLE webknossos.annotation_privateLinks ALTER COLUMN _id SET DEFAULT '';
ALTER TABLE webknossos.shortLinks ALTER COLUMN _id SET DEFAULT '';

UPDATE webknossos.releaseInformation SET schemaVersion = 90;

COMMIT;

48 changes: 25 additions & 23 deletions tools/postgres/schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -19,15 +19,15 @@ START TRANSACTION;
CREATE TABLE webknossos.releaseInformation (
schemaVersion BIGINT NOT NULL
);
INSERT INTO webknossos.releaseInformation(schemaVersion) values(89);
INSERT INTO webknossos.releaseInformation(schemaVersion) values(90);
COMMIT TRANSACTION;


CREATE TYPE webknossos.ANNOTATION_TYPE AS ENUM ('Task', 'Explorational', 'TracingBase', 'Orphan');
CREATE TYPE webknossos.ANNOTATION_STATE AS ENUM ('Active', 'Finished', 'Cancelled', 'Initializing');
CREATE TYPE webknossos.ANNOTATION_VISIBILITY AS ENUM ('Private', 'Internal', 'Public');
CREATE TABLE webknossos.annotations(
_id CHAR(24) PRIMARY KEY NOT NULL DEFAULT '',
_id CHAR(24) PRIMARY KEY,
_dataSet CHAR(24) NOT NULL,
_task CHAR(24),
_team CHAR(24) NOT NULL,
Expand Down Expand Up @@ -74,7 +74,7 @@ CREATE TABLE webknossos.annotation_contributors(
);

CREATE TABLE webknossos.meshes(
_id CHAR(24) PRIMARY KEY NOT NULL DEFAULT '',
_id CHAR(24) PRIMARY KEY,
_annotation CHAR(24) NOT NULL,
description TEXT NOT NULL DEFAULT '',
position webknossos.VECTOR3 NOT NULL,
Expand All @@ -84,7 +84,7 @@ CREATE TABLE webknossos.meshes(
);

CREATE TABLE webknossos.publications(
_id CHAR(24) PRIMARY KEY DEFAULT '',
_id CHAR(24) PRIMARY KEY,
publicationDate TIMESTAMPTZ,
imageUrl VARCHAR(2048),
title VARCHAR(2048),
Expand All @@ -94,8 +94,8 @@ CREATE TABLE webknossos.publications(
);

CREATE TABLE webknossos.dataSets(
_id CHAR(24) PRIMARY KEY DEFAULT '',
_dataStore CHAR(256) NOT NULL,
_id CHAR(24) PRIMARY KEY,
_dataStore VARCHAR(256) NOT NULL,
_organization CHAR(24) NOT NULL,
_publication CHAR(24),
_uploader CHAR(24),
Expand Down Expand Up @@ -180,7 +180,7 @@ CREATE TABLE webknossos.tracingStores(
);

CREATE TABLE webknossos.projects(
_id CHAR(24) PRIMARY KEY DEFAULT '',
_id CHAR(24) PRIMARY KEY,
_organization CHAR(24) NOT NULL,
_team CHAR(24) NOT NULL,
_owner CHAR(24) NOT NULL,
Expand All @@ -194,7 +194,7 @@ CREATE TABLE webknossos.projects(
);

CREATE TABLE webknossos.scripts(
_id CHAR(24) PRIMARY KEY DEFAULT '',
_id CHAR(24) PRIMARY KEY,
_owner CHAR(24) NOT NULL,
name VARCHAR(256) NOT NULL CHECK (name ~* '^[A-Za-z0-9\-_\. ß]+$'),
gist VARCHAR(1024) NOT NULL,
Expand All @@ -206,7 +206,7 @@ CREATE TABLE webknossos.scripts(
CREATE TYPE webknossos.TASKTYPE_MODES AS ENUM ('orthogonal', 'flight', 'oblique', 'volume');
CREATE TYPE webknossos.TASKTYPE_TRACINGTYPES AS ENUM ('skeleton', 'volume', 'hybrid');
CREATE TABLE webknossos.taskTypes(
_id CHAR(24) PRIMARY KEY DEFAULT '',
_id CHAR(24) PRIMARY KEY,
_organization CHAR(24) NOT NULL,
_team CHAR(24) NOT NULL,
summary VARCHAR(256) NOT NULL,
Expand All @@ -228,7 +228,7 @@ CREATE TABLE webknossos.taskTypes(
);

CREATE TABLE webknossos.tasks(
_id CHAR(24) PRIMARY KEY DEFAULT '',
_id CHAR(24) PRIMARY KEY,
_project CHAR(24) NOT NULL,
_script CHAR(24),
_taskType CHAR(24) NOT NULL,
Expand All @@ -253,7 +253,7 @@ CREATE TABLE webknossos.experienceDomains(
);

CREATE TABLE webknossos.teams(
_id CHAR(24) PRIMARY KEY DEFAULT '',
_id CHAR(24) PRIMARY KEY,
_organization CHAR(24) NOT NULL,
name VARCHAR(256) NOT NULL CHECK (name ~* '^[A-Za-z0-9\-_\. ß]+$'),
created TIMESTAMPTZ NOT NULL DEFAULT NOW(),
Expand All @@ -263,7 +263,7 @@ CREATE TABLE webknossos.teams(
);

CREATE TABLE webknossos.timespans(
_id CHAR(24) PRIMARY KEY DEFAULT '',
_id CHAR(24) PRIMARY KEY,
_user CHAR(24) NOT NULL,
_annotation CHAR(24),
time BIGINT NOT NULL,
Expand All @@ -275,7 +275,7 @@ CREATE TABLE webknossos.timespans(

CREATE TYPE webknossos.PRICING_PLANS AS ENUM ('Basic', 'Premium', 'Pilot', 'Custom');
CREATE TABLE webknossos.organizations(
_id CHAR(24) PRIMARY KEY DEFAULT '',
_id CHAR(24) PRIMARY KEY,
name VARCHAR(256) NOT NULL UNIQUE,
additionalInformation VARCHAR(2048) NOT NULL DEFAULT '',
logoUrl VARCHAR(2048) NOT NULL DEFAULT '',
Expand All @@ -290,7 +290,7 @@ CREATE TABLE webknossos.organizations(

CREATE TYPE webknossos.USER_PASSWORDINFO_HASHERS AS ENUM ('SCrypt');
CREATE TABLE webknossos.users(
_id CHAR(24) PRIMARY KEY DEFAULT '',
_id CHAR(24) PRIMARY KEY,
_multiUser CHAR(24) NOT NULL,
_organization CHAR(24) NOT NULL,
firstName VARCHAR(256) NOT NULL, -- CHECK (firstName ~* '^[A-Za-z0-9\-_ ]+$'),
Expand Down Expand Up @@ -342,7 +342,7 @@ CREATE TABLE webknossos.user_dataSetLayerConfigurations(

CREATE TYPE webknossos.THEME AS ENUM ('light', 'dark', 'auto');
CREATE TABLE webknossos.multiUsers(
_id CHAR(24) PRIMARY KEY DEFAULT '',
_id CHAR(24) PRIMARY KEY,
email VARCHAR(512) NOT NULL UNIQUE CHECK (email ~* '^.+@.+$'),
passwordInfo_hasher webknossos.USER_PASSWORDINFO_HASHERS NOT NULL DEFAULT 'SCrypt',
passwordInfo_password VARCHAR(512) NOT NULL,
Expand All @@ -359,7 +359,7 @@ CREATE TABLE webknossos.multiUsers(
CREATE TYPE webknossos.TOKEN_TYPES AS ENUM ('Authentication', 'DataStore', 'ResetPassword');
CREATE TYPE webknossos.USER_LOGININFO_PROVDERIDS AS ENUM ('credentials');
CREATE TABLE webknossos.tokens(
_id CHAR(24) PRIMARY KEY DEFAULT '',
_id CHAR(24) PRIMARY KEY,
value Text NOT NULL,
loginInfo_providerID webknossos.USER_LOGININFO_PROVDERIDS NOT NULL,
loginInfo_providerKey VARCHAR(512) NOT NULL,
Expand All @@ -378,8 +378,8 @@ INSERT INTO webknossos.maintenance(maintenanceExpirationTime) values('2000-01-01


CREATE TABLE webknossos.workers(
_id CHAR(24) PRIMARY KEY DEFAULT '',
_dataStore CHAR(256) NOT NULL,
_id CHAR(24) PRIMARY KEY,
_dataStore VARCHAR(256) NOT NULL,
key VARCHAR(1024) NOT NULL UNIQUE,
maxParallelJobs INT NOT NULL DEFAULT 1,
lastHeartBeat TIMESTAMPTZ NOT NULL DEFAULT '2000-01-01T00:00:00Z',
Expand All @@ -391,9 +391,9 @@ CREATE TABLE webknossos.workers(
CREATE TYPE webknossos.JOB_STATE AS ENUM ('PENDING', 'STARTED', 'SUCCESS', 'FAILURE', 'CANCELLED');

CREATE TABLE webknossos.jobs(
_id CHAR(24) PRIMARY KEY DEFAULT '',
_id CHAR(24) PRIMARY KEY,
_owner CHAR(24) NOT NULL,
_dataStore CHAR(256) NOT NULL,
_dataStore VARCHAR(256) NOT NULL,
command TEXT NOT NULL,
commandArgs JSONB NOT NULL,
state webknossos.JOB_STATE NOT NULL DEFAULT 'PENDING', -- always updated by the worker
Expand All @@ -409,7 +409,7 @@ CREATE TABLE webknossos.jobs(


CREATE TABLE webknossos.invites(
_id CHAR(24) PRIMARY KEY DEFAULT '',
_id CHAR(24) PRIMARY KEY,
tokenValue Text NOT NULL,
_organization CHAR(24) NOT NULL,
autoActivate BOOLEAN NOT NULL,
Expand All @@ -419,15 +419,15 @@ CREATE TABLE webknossos.invites(
);

CREATE TABLE webknossos.annotation_privateLinks(
_id CHAR(24) PRIMARY KEY DEFAULT '',
_id CHAR(24) PRIMARY KEY,
_annotation CHAR(24) NOT NULL,
accessToken Text NOT NULL UNIQUE,
expirationDateTime TIMESTAMPTZ,
isDeleted BOOLEAN NOT NULL DEFAULT false
);

CREATE TABLE webknossos.shortLinks(
_id CHAR(24) PRIMARY KEY DEFAULT '',
_id CHAR(24) PRIMARY KEY,
key CHAR(16) NOT NULL UNIQUE,
longLink Text NOT NULL
);
Expand Down Expand Up @@ -662,6 +662,8 @@ ALTER TABLE webknossos.jobs
ADD CONSTRAINT owner_ref FOREIGN KEY(_owner) REFERENCES webknossos.users(_id) DEFERRABLE,
ADD CONSTRAINT dataStore_ref FOREIGN KEY(_dataStore) REFERENCES webknossos.dataStores(name) DEFERRABLE,
ADD CONSTRAINT worker_ref FOREIGN KEY(_worker) REFERENCES webknossos.workers(_id) DEFERRABLE;
ALTER TABLE webknossos.workers
ADD CONSTRAINT dataStore_ref FOREIGN KEY(_dataStore) REFERENCES webknossos.dataStores(name) DEFERRABLE;
ALTER TABLE webknossos.annotation_privateLinks
ADD CONSTRAINT annotation_ref FOREIGN KEY(_annotation) REFERENCES webknossos.annotations(_id) DEFERRABLE;

Expand Down