diff --git a/00-init.sql b/00-tables.sql similarity index 81% rename from 00-init.sql rename to 00-tables.sql index e274457793218dec4cd8c82698022e1e3a859969..925bdaf8bf9954af5e7d2df3e195e73b4d04e2f1 100644 --- a/00-init.sql +++ b/00-tables.sql @@ -1,34 +1,6 @@ -/**_____________________________________________________________________________ - * - * OATS - INAF - * Osservatorio Astronomico di Tireste - Istituto Nazionale di Astrofisica - * Astronomical Observatory of Trieste - National Institute for Astrophysics - * ____________________________________________________________________________ - * - * Copyright (C) 2020 Istituto Nazionale di Astrofisica - * - * This program is free software; you can redistribute it and/or - * modify it under the terms of the GNU General Public License - * as published by the Free Software Foundation; either version 2 - * 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 General Public License for more details. - * - * You should have received a copy of the GNU General Public License - * along with this program; if not, write to the Free Software Foundation, Inc., - * 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA. - * _____________________________________________________________________________ - **/ - -/* - VOSpace front-end -*/ - CREATE EXTENSION IF NOT EXISTS ltree; + CREATE TYPE NodeType AS ENUM ('container', 'data', 'link', 'structured'); CREATE TYPE LocationType AS ENUM ('async', 'portal', 'user'); CREATE TYPE StorageType AS ENUM ('cold', 'hot', 'local', 'portal'); @@ -93,6 +65,8 @@ CREATE TABLE node ( FOREIGN KEY (location_id) REFERENCES location (location_id) ); +CREATE INDEX file_name_idx ON node USING btree(name); + CREATE TABLE deleted_node ( node_id BIGSERIAL NOT NULL, @@ -142,3 +116,39 @@ CREATE TABLE users ( e_mail VARCHAR NOT NULL, PRIMARY KEY (user_id) ); + + +CREATE TYPE JobPhaseEnum AS ENUM ('PENDING', 'QUEUED', 'EXECUTING', 'ABORTED', 'COMPLETED', 'HELD', 'SUSPENDED', 'ERROR', 'ARCHIVED'); +CREATE TYPE ErrorType AS ENUM('transient','fatal'); + +CREATE TABLE job ( + job_id varchar not null, + owner_id varchar not null, + job_type varchar not null, + phase JobPhaseEnum not null, + start_time timestamp, + end_time timestamp, + creation_time timestamp default CURRENT_TIMESTAMP, + job_info jsonb, + processed_blocks int default null, + total_blocks int default null, + results jsonb, + error_message varchar, + error_type ErrorType, + error_has_detail boolean, + error_detail varchar, + primary key(job_id) +); + +CREATE INDEX owner_idx ON job USING btree(owner_id); + + +-- Stores the content of StructuredDataNodes representing a list of files. + +CREATE TABLE list_of_files ( + list_node_id BIGSERIAL NOT NULL, + node_id BIGSERIAL NOT NULL, + PRIMARY KEY (list_node_id, node_id), + FOREIGN KEY (list_node_id) REFERENCES node (node_id), + FOREIGN KEY (node_id) REFERENCES node (node_id) +); diff --git a/01-paths-indexes.sql b/01-paths-indexes.sql new file mode 100644 index 0000000000000000000000000000000000000000..6f5d39fad2c0d35c2e693994d699b1b27edaa775 --- /dev/null +++ b/01-paths-indexes.sql @@ -0,0 +1,34 @@ +-- Generates the path from parent_path and id +CREATE OR REPLACE FUNCTION path(parent_path ltree, id bigint) RETURNS ltree AS +$func$ +BEGIN + RETURN text2ltree(CASE + WHEN parent_path IS NULL THEN '' + WHEN parent_path::varchar = '' THEN id::varchar + ELSE (parent_path::varchar || '.' || id::varchar) + END); +END +$func$ LANGUAGE plpgsql IMMUTABLE; + +-- Testing the function +SELECT CASE WHEN +path(NULL, 0) = text2ltree('') +AND path(text2ltree(''), 1) = text2ltree('1') +AND path(text2ltree('1'), 2) = text2ltree('1.2') +THEN 'PASSED' ELSE 'FAILED' END AS test; + + +-- Create node path indexes and generated columns using the previously defined function + +CREATE INDEX file_parent_path_gist_idx ON node USING GIST(parent_path); +CREATE INDEX file_parent_path_idx ON node USING btree(parent_path); + +ALTER TABLE node ADD COLUMN path ltree GENERATED ALWAYS AS (path(parent_path, node_id)) STORED; +CREATE INDEX file_path_gist_idx ON node USING GIST(path); +CREATE UNIQUE INDEX file_path_idx ON node USING btree(path); + +ALTER TABLE node ADD COLUMN relative_path ltree GENERATED ALWAYS AS (path(parent_relative_path, node_id)) STORED; +CREATE INDEX file_rel_path_gist_idx ON node USING GIST(relative_path); + +-- Create root node +INSERT INTO node (parent_path, parent_relative_path, name, type, creator_id, location_id, is_public) VALUES (NULL, NULL, '', 'container', '0', 1, true); diff --git a/01-pgsql_path.sql b/01-pgsql_path.sql deleted file mode 100644 index 3d6eeb50e08060004702c68a7713f41dba0703cc..0000000000000000000000000000000000000000 --- a/01-pgsql_path.sql +++ /dev/null @@ -1,23 +0,0 @@ -/* - Author: Sonia Zorba - Email: sonia.zorba@inaf.it -*/ - --- Generates the path from parent_path and id -CREATE OR REPLACE FUNCTION path(parent_path ltree, id bigint) RETURNS ltree AS -$func$ -BEGIN - RETURN text2ltree(CASE - WHEN parent_path IS NULL THEN '' - WHEN parent_path::varchar = '' THEN id::varchar - ELSE (parent_path::varchar || '.' || id::varchar) - END); -END -$func$ LANGUAGE plpgsql IMMUTABLE; - --- Testing the function -SELECT CASE WHEN -path(NULL, 0) = text2ltree('') -AND path(text2ltree(''), 1) = text2ltree('1') -AND path(text2ltree('1'), 2) = text2ltree('1.2') -THEN 'PASSED' ELSE 'FAILED' END AS test; \ No newline at end of file diff --git a/02-indexes.sql b/02-indexes.sql deleted file mode 100644 index d863d140e9828638dcd2befc06cb06c669090cc5..0000000000000000000000000000000000000000 --- a/02-indexes.sql +++ /dev/null @@ -1,16 +0,0 @@ -/* - Author: Sonia Zorba - Email: sonia.zorba@inaf.it -*/ - -CREATE INDEX file_name_idx ON node USING btree(name); - -CREATE INDEX file_parent_path_gist_idx ON node USING GIST(parent_path); -CREATE INDEX file_parent_path_idx ON node USING btree(parent_path); - -ALTER TABLE node ADD COLUMN path ltree GENERATED ALWAYS AS (path(parent_path, node_id)) STORED; -CREATE INDEX file_path_gist_idx ON node USING GIST(path); -CREATE UNIQUE INDEX file_path_idx ON node USING btree(path); - -ALTER TABLE node ADD COLUMN relative_path ltree GENERATED ALWAYS AS (path(parent_relative_path, node_id)) STORED; -CREATE INDEX file_rel_path_gist_idx ON node USING GIST(relative_path); diff --git a/03-os_path_view.sql b/02-views.sql similarity index 79% rename from 03-os_path_view.sql rename to 02-views.sql index cab656ec9594821c3adcd8e2f9522d33b9c88a81..45ce30831a23d1d23d5fdd40fb8bdd009fc792df 100644 --- a/03-os_path_view.sql +++ b/02-views.sql @@ -1,11 +1,4 @@ -/* - Author: Sonia Zorba - Email: sonia.zorba@inaf.it -*/ - --- This view allows to obtain the the ltree_path from the os_path --- Example query: --- SELECT path FROM node n JOIN node_os_path o ON n.node_id = o.node_id WHERE os_path = '/curban/store'; +-- View that maps node_id to os_path (relative path of file on disk) CREATE VIEW node_os_path AS SELECT node_id, '/' AS os_path FROM node WHERE path = '' @@ -21,7 +14,7 @@ FROM ( ORDER BY p.node_id, nlevel(n.path) ) AS j GROUP BY node_id; --- View that maps node_id to vos_path +-- View that maps node_id to vos_path (path in VOSpace) CREATE VIEW node_vos_path AS SELECT node_id, '/' AS vos_path FROM node WHERE path = '' @@ -37,9 +30,12 @@ FROM ( ORDER BY p.node_id, nlevel(n.path) ) AS j GROUP BY node_id; --- This view allows to obtain the the os_path from the vos_path +-- View that combines the two previous views to obtain the os_path from the vos_path and vice versa CREATE VIEW node_path AS SELECT v.node_id, vos_path, os_path FROM node_vos_path v LEFT JOIN node_os_path o ON o.node_id = v.node_id; + +-- Example query to obtain the the ltree_path from the os_path: +-- SELECT path FROM node n JOIN node_os_path o ON n.node_id = o.node_id WHERE os_path = '/curban/store'; diff --git a/08-update_array.sql b/03-other-functions.sql similarity index 100% rename from 08-update_array.sql rename to 03-other-functions.sql diff --git a/04-pgsql_os_path_recursive.sql b/04-pgsql_os_path_recursive.sql deleted file mode 100644 index 6d622ce8d21147023bc6e8672f0ed140eb92d78e..0000000000000000000000000000000000000000 --- a/04-pgsql_os_path_recursive.sql +++ /dev/null @@ -1,21 +0,0 @@ -/* - Author: Sonia Zorba - Email: sonia.zorba@inaf.it -*/ - --- Generate the os_path from the node id --- It could be used for initializing the os_path generated column -CREATE OR REPLACE FUNCTION get_os_path(input_id int) RETURNS varchar AS -$func$ -SELECT string_agg(name, '/') FROM ( - WITH RECURSIVE paths AS ( - SELECT node_id, name, path, parent_path, 1 AS level - FROM node - WHERE node_id = input_id - UNION ALL - SELECT f.node_id, f.name, f.path, f.parent_path, p.level + 1 - FROM node f - INNER JOIN paths p ON p.parent_path = f.path - ) SELECT name FROM paths ORDER BY LEVEL DESC -) AS names; -$func$ LANGUAGE sql; diff --git a/05-data.sql b/05-data.sql deleted file mode 100644 index 27bda0885782401ba0dfac5170d6a56fae195766..0000000000000000000000000000000000000000 --- a/05-data.sql +++ /dev/null @@ -1,45 +0,0 @@ -/* - Initialization test for storage table -*/ - -INSERT INTO storage (storage_type, base_path, base_url, hostname) VALUES ('cold', '/ia2_tape_generic_rw_01/users', NULL, 'tape-fe.ia2.inaf.it'); -INSERT INTO storage (storage_type, base_path, base_url, hostname) VALUES ('hot', '/mnt/hot_storage/users', NULL, 'server'); -INSERT INTO storage (storage_type, base_path, base_url, hostname) VALUES ('local', '/home', NULL, 'localhost'); -INSERT INTO storage (storage_type, base_path, base_url, hostname) VALUES ('local', '/home/vospace/upload', NULL, 'localhost'); -INSERT INTO storage (storage_type, base_path, base_url, hostname) VALUES ('portal', NULL, '/files/new/lbt', 'archive.lbto.org'); - - -/* - Initialization test for location table -*/ - -INSERT INTO location (location_type, storage_src_id, storage_dest_id) VALUES ('async', 1, 3); -INSERT INTO location (location_type, storage_src_id, storage_dest_id) VALUES ('async', 2, 3); -INSERT INTO location (location_type, storage_src_id, storage_dest_id) VALUES ('user', 4, 4); -INSERT INTO location (location_type, storage_src_id, storage_dest_id) VALUES ('portal', 5, 5); - - -/* - Initialization test for vospace node table -*/ - - --- parent_path = parent_relative_path -INSERT INTO node (parent_path, parent_relative_path, name, type, creator_id, is_public, sticky) VALUES (NULL, NULL, '', 'container', '0', true, true); -- / -INSERT INTO node (parent_path, parent_relative_path, name, type, creator_id, sticky) VALUES ('', NULL, 'cristiano.urban', 'container', '3354', true); -- /curban -INSERT INTO node (parent_path, parent_relative_path, name, type, creator_id, sticky) VALUES ('', NULL, 'sara.bertocco', 'container', '2048', true); -- /sbertocco -INSERT INTO node (parent_path, parent_relative_path, name, type, creator_id, sticky) VALUES ('', NULL, 'sonia.zorba', 'container', '2386', true); -- /szorba --- parent_path <> parent_relative_path -INSERT INTO node (parent_path, parent_relative_path, name, type, creator_id, group_read, group_write) VALUES ('', NULL, 'test', 'container', '2386', '{"VOSpace.test1"}','{"VOSpace.test1"}'); -- /test -INSERT INTO node (parent_path, parent_relative_path, name, type, creator_id) VALUES ('5', '', 'f1', 'container', '2386'); -- /test/f1 (rel: /f1) -INSERT INTO node (parent_path, parent_relative_path, name, os_name, type, creator_id, location_id) VALUES ('5.6', '6', 'f2_renamed', 'f2', 'container', '2386', 1); -- /test/f1/f2_renamed (rel: /f1/f2) -INSERT INTO node (parent_path, parent_relative_path, name, type, creator_id, location_id) VALUES ('5.6.7', '6.7', 'f3', 'data', '2386', 1); -- /test/f1/f2_renamed/f3 (rel: /f1/f2/f3) - - -/* - Initialization test for vospace users table -*/ - -INSERT INTO Users (user_id, user_name, e_mail) VALUES ('3354', 'cristiano.urban', 'cristiano.urban@inaf.it'); -INSERT INTO Users (user_id, user_name, e_mail) VALUES ('2048', 'sara.bertocco', 'sara.bertocco@inaf.it'); -INSERT INTO Users (user_id, user_name, e_mail) VALUES ('2386', 'sonia.zorba', 'sonia.zorba@inaf.it'); diff --git a/06-uws.sql b/06-uws.sql deleted file mode 100644 index b4a8859ef458ef3d133a84165332810c44a3001b..0000000000000000000000000000000000000000 --- a/06-uws.sql +++ /dev/null @@ -1,25 +0,0 @@ -CREATE TYPE JobPhaseEnum AS ENUM ('PENDING', 'QUEUED', 'EXECUTING', 'ABORTED', 'COMPLETED', 'HELD', 'SUSPENDED', 'ERROR', 'ARCHIVED'); --- CREATE TYPE JobTypeEnum AS ENUM ('pushToVoSpace', 'pullToVoSpace', 'pullFromVoSpace', 'pushFromVoSpace', 'moveNode', 'copyNode', 'other'); -CREATE TYPE ErrorType AS ENUM('transient','fatal'); - -CREATE TABLE job ( - job_id varchar not null, - owner_id varchar not null, --- job_type JobTypeEnum not null, - job_type varchar not null, - phase JobPhaseEnum not null, - start_time timestamp, - end_time timestamp, - creation_time timestamp default CURRENT_TIMESTAMP, - job_info jsonb, - processed_blocks int default null, - total_blocks int default null, - results jsonb, - error_message varchar, - error_type ErrorType, - error_has_detail boolean, - error_detail varchar, - primary key(job_id) -); - -CREATE INDEX owner_idx ON job USING btree(owner_id); diff --git a/07-list-of-files.sql b/07-list-of-files.sql deleted file mode 100644 index d99135485d3b4c8c07ffad2fa1c1e704b18fde8a..0000000000000000000000000000000000000000 --- a/07-list-of-files.sql +++ /dev/null @@ -1,10 +0,0 @@ - --- Stores the content of StructuredDataNodes representing a list of files. - -CREATE TABLE list_of_files ( - list_node_id BIGSERIAL NOT NULL, - node_id BIGSERIAL NOT NULL, - PRIMARY KEY (list_node_id, node_id), - FOREIGN KEY (list_node_id) REFERENCES node (node_id), - FOREIGN KEY (node_id) REFERENCES node (node_id) -); diff --git a/LICENSE b/LICENSE new file mode 100644 index 0000000000000000000000000000000000000000..a17a7b0996d0d9196339a41e52f5535ad31a188c --- /dev/null +++ b/LICENSE @@ -0,0 +1,23 @@ +_____________________________________________________________________________ + + OATS - INAF + Osservatorio Astronomico di Tireste - Istituto Nazionale di Astrofisica + Astronomical Observatory of Trieste - National Institute for Astrophysics +____________________________________________________________________________ + +Copyright (C) 2020-2021 Istituto Nazionale di Astrofisica + +This program is free software; you can redistribute it and/or +modify it under the terms of the GNU General Public License +as published by the Free Software Foundation; either version 2 +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 General Public License for more details. + +You should have received a copy of the GNU General Public License +along with this program; if not, write to the Free Software Foundation, Inc., +51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA. +_____________________________________________________________________________ diff --git a/README.md b/README.md new file mode 100644 index 0000000000000000000000000000000000000000..e20fa93ecc07d3252f3dca2487aad8e969bd77ca --- /dev/null +++ b/README.md @@ -0,0 +1,7 @@ +# VOSpace File Catalog (database) + +**⚠ Work in progress! ⚠** + +This repository defines the VOSpace database structure. + +It consists in a PostgreSQL database with the [ltree](https://www.postgresql.org/docs/12/ltree.html) extension. SQL files are named starting with a number because they are put in a Docker image where they have to be executed in order.