From ef92659404de079649be7cfb2b531e6066493823 Mon Sep 17 00:00:00 2001
From: Cristiano Urban <cristiano.urban@inaf.it>
Date: Wed, 20 Jan 2021 12:16:32 +0100
Subject: [PATCH] Code cleanup + added some initializations.

Signed-off-by: Cristiano Urban <cristiano.urban@inaf.it>
---
 00-init.sql                    | 32 ++++++++++----------------------
 02-indexes.sql                 | 16 ++++++++--------
 03-os_path_view.sql            | 14 +++++++-------
 04-pgsql_os_path_recursive.sql |  6 +++---
 05-data.sql                    | 20 ++++++++++----------
 06-uws.sql                     |  9 ++++-----
 6 files changed, 42 insertions(+), 55 deletions(-)

diff --git a/00-init.sql b/00-init.sql
index 7956ed8..f02254b 100644
--- a/00-init.sql
+++ b/00-init.sql
@@ -32,7 +32,7 @@ CREATE EXTENSION IF NOT EXISTS ltree;
 CREATE TYPE NodeType AS ENUM ('container', 'data', 'link');
 CREATE TYPE LocationType AS ENUM ('virtual', 'tape', 'user', 'LBT');
 
-CREATE TABLE Node (
+CREATE TABLE node (
     node_id                BIGSERIAL     NOT NULL,
     parent_path            LTREE         default NULL,
     parent_relative_path   LTREE         default NULL,
@@ -40,12 +40,11 @@ CREATE TABLE Node (
     os_name                VARCHAR       default NULL,
     tstamp_wrapper_dir     VARCHAR       default NULL,
     type                   NodeType      NOT NULL,
-    location_type          LocationType  default NULL,
+    location_type          LocationType  default 'virtual',
     format                 VARCHAR       default NULL,
-    -- format serve per distinguere unstuctured (format=NULL) da structured che hanno un formato noto
-    async_trans            BOOLEAN       default NULL,
-    -- async_trans serve per indicare se il nodo e` ospitato da un cold storage e deve essere necessariamente 
-    -- trasferito con un trasferimento asincrono 
+    -- format is used to distinguish between unstuctured (format=NULL) and structured nodes having a well defined format
+    async_trans            BOOLEAN       default false,
+    -- async_trans tells us whether a node is hosted on a cold storage and has to be transferred asynchronously
     busy_state             BOOLEAN       default NULL,
     owner_id               VARCHAR       default NULL,
     creator_id             VARCHAR       default NULL,
@@ -53,8 +52,8 @@ CREATE TABLE Node (
     group_write            VARCHAR[]     default NULL,
     is_public              BOOLEAN       default NULL,
     delta                  BIGINT        default NULL,
-    /* potrebbe essere un delta di dati trasferito durante un trasferimento asincrono.
-       Dovrebbe stare sul servizio che fa il trasferimento  (es. redis) */
+    /* it may be a delta of data which is transferred through an asynchronous transfer.
+       It should stay on the transfer service (e.g. Redis) */
     content_type           VARCHAR       default NULL,
     content_encoding       VARCHAR       default NULL,
     content_length         BIGINT        default NULL,
@@ -64,25 +63,14 @@ CREATE TABLE Node (
     -- link                  TEXT          default NULL,
     accept_views           TEXT[]        default NULL,
     provide_views          TEXT[]        default NULL,
-    -- serve per mappare il nome del servizio di storage da interrogare per accedere al contenuto di questo nodo 
+    -- storage service mapping used to access the content of this node 
     -- storage_id            VARCHAR,    
     protocols              TEXT[]        default NULL,
     PRIMARY KEY (node_id)
 );
 
 
-CREATE TABLE NodeProperty (
-    node_id           BIGSERIAL,
-    property_uri      VARCHAR       NOT NULL,
-    property_value    VARCHAR       default NULL,
-    last_modified     TIMESTAMP     default CURRENT_TIMESTAMP,
-    -- support replication with a fake primary key
-    -- _rep_support     BIGINT       NOT NULL PRIMARY KEY,
-    foreign key (node_id) references Node (node_id)
-);
-
-
-CREATE TABLE DeletedNode (
+CREATE TABLE deleted_node (
     node_id           BIGSERIAL     NOT NULL,
     name              VARCHAR       NOT NULL,
     owner_id          VARCHAR       NOT NULL,
@@ -91,7 +79,7 @@ CREATE TABLE DeletedNode (
 );
 
 
-CREATE TABLE Users (
+CREATE TABLE users (
     rap_id            VARCHAR       NOT NULL,
     user_name         VARCHAR       NOT NULL,
     e_mail            VARCHAR       NOT NULL,
diff --git a/02-indexes.sql b/02-indexes.sql
index 17159eb..d863d14 100644
--- a/02-indexes.sql
+++ b/02-indexes.sql
@@ -3,14 +3,14 @@
     Email: sonia.zorba@inaf.it
 */
 
-CREATE INDEX file_name_idx ON Node USING btree(name);
+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);
+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 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);
+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/03-os_path_view.sql
index e7961b4..cab656e 100644
--- a/03-os_path_view.sql
+++ b/03-os_path_view.sql
@@ -5,18 +5,18 @@
 
 -- 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';
+-- SELECT path FROM node n JOIN node_os_path o ON n.node_id = o.node_id WHERE os_path = '/curban/store';
 
 CREATE VIEW node_os_path AS
-SELECT node_id, '/' AS os_path FROM Node WHERE path = ''
+SELECT node_id, '/' AS os_path FROM node WHERE path = ''
 UNION
 SELECT node_id, '/' || string_agg(name, '/') AS os_path
 FROM (
     SELECT (CASE WHEN os_name IS NOT NULL THEN os_name ELSE name END) AS name, p.node_id
-    FROM Node n
+    FROM node n
     JOIN (
         SELECT UNNEST(string_to_array(relative_path::varchar, '.')) AS rel_id, node_id
-        FROM Node
+        FROM node
     ) AS p ON n.node_id::varchar = p.rel_id
     ORDER BY p.node_id, nlevel(n.path)
 ) AS j GROUP BY node_id;
@@ -24,15 +24,15 @@ FROM (
 -- View that maps node_id to vos_path
 
 CREATE VIEW node_vos_path AS
-SELECT node_id, '/' AS vos_path FROM Node WHERE path = ''
+SELECT node_id, '/' AS vos_path FROM node WHERE path = ''
 UNION
 SELECT node_id, '/' || string_agg(name, '/') AS os_path
 FROM (
     SELECT name, p.node_id
-    FROM Node n
+    FROM node n
     JOIN (
         SELECT UNNEST(string_to_array(path::varchar, '.')) AS rel_id, node_id
-        FROM Node
+        FROM node
     ) AS p ON n.node_id::varchar = p.rel_id
     ORDER BY p.node_id, nlevel(n.path)
 ) AS j GROUP BY node_id;
diff --git a/04-pgsql_os_path_recursive.sql b/04-pgsql_os_path_recursive.sql
index 9169033..6d622ce 100644
--- a/04-pgsql_os_path_recursive.sql
+++ b/04-pgsql_os_path_recursive.sql
@@ -3,18 +3,18 @@
     Email: sonia.zorba@inaf.it
 */
 
--- Generate the os_path from the Node id
+-- 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
+            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
+            FROM node f
             INNER JOIN paths p ON p.parent_path = f.path
     ) SELECT name FROM paths ORDER BY LEVEL DESC
 ) AS names;
diff --git a/05-data.sql b/05-data.sql
index b6b1481..85a8d1e 100644
--- a/05-data.sql
+++ b/05-data.sql
@@ -1,20 +1,20 @@
 /*
-   Initialization test for vospace Node table; for now owner_id and group_id are set equal to the rap_id
+   Initialization test for vospace node table; for now owner_id and group_id are set equal to the rap_id
 */
 
 -- parent_path = parent_relative_path
-INSERT INTO Node (parent_path, parent_relative_path, name, type, owner_id, creator_id) VALUES (NULL, NULL, '', 'container', '0', '0');                -- /
-INSERT INTO Node (parent_path, parent_relative_path, name, type, owner_id, creator_id) VALUES ('', '', 'curban', 'container', '3354', '3354');      -- /curban
-INSERT INTO Node (parent_path, parent_relative_path, name, type, owner_id, creator_id) VALUES ('', '', 'sbertocco', 'container', '2048', '2048');   -- /sbertocco
-INSERT INTO Node (parent_path, parent_relative_path, name, type, owner_id, creator_id) VALUES ('', '', 'szorba', 'container', '2386', '2386');      -- /szorba
+INSERT INTO node (parent_path, parent_relative_path, name, type, owner_id, creator_id) VALUES (NULL, NULL, '', 'container', '0', '0');                                                                                -- /
+INSERT INTO node (parent_path, parent_relative_path, name, type, owner_id, creator_id) VALUES ('', '', 'curban', 'container', '3354', '3354');                                                                        -- /curban
+INSERT INTO node (parent_path, parent_relative_path, name, type, owner_id, creator_id) VALUES ('', '', 'sbertocco', 'container', '2048', '2048');                                                                     -- /sbertocco
+INSERT INTO node (parent_path, parent_relative_path, name, type, owner_id, creator_id) VALUES ('', '', 'szorba', 'container', '2386', '2386');                                                                        -- /szorba
 -- parent_path <> parent_relative_path
-INSERT INTO Node (parent_path, parent_relative_path, name, type, owner_id, creator_id, group_read, group_write) VALUES ('', NULL, 'test', 'container', '2386', '2386', '{"VOSpace.test1"}','{"VOSpace.test1"}');      -- /test
-INSERT INTO Node (parent_path, parent_relative_path, name, type, owner_id, creator_id) VALUES ('5', '', 'f1', 'container', '2386', '2386');      -- /test/f1 (rel: /f1)
-INSERT INTO Node (parent_path, parent_relative_path, name, os_name, type, owner_id, creator_id) VALUES ('5.6', '6', 'f2_renamed', 'f2', 'container', '2386', '2386');      -- /test/f1/f2_renamed (rel: /f1/f2)
-INSERT INTO Node (parent_path, parent_relative_path, name, type, owner_id, creator_id) VALUES ('5.6.7', '6.7', 'f3', 'data', '2386', '2386');      -- /test/f1/f2_renamed/f3 (rel: /f1/f2/f3)
+INSERT INTO node (parent_path, parent_relative_path, name, type, owner_id, creator_id, group_read, group_write) VALUES ('', NULL, 'test', 'container', '2386', '2386', '{"VOSpace.test1"}','{"VOSpace.test1"}');      -- /test
+INSERT INTO node (parent_path, parent_relative_path, name, type, owner_id, creator_id) VALUES ('5', '', 'f1', 'container', '2386', '2386');                                                                           -- /test/f1 (rel: /f1)
+INSERT INTO node (parent_path, parent_relative_path, name, os_name, type, owner_id, creator_id) VALUES ('5.6', '6', 'f2_renamed', 'f2', 'container', '2386', '2386');                                                 -- /test/f1/f2_renamed (rel: /f1/f2)
+INSERT INTO node (parent_path, parent_relative_path, name, type, owner_id, creator_id) VALUES ('5.6.7', '6.7', 'f3', 'data', '2386', '2386');                                                                         -- /test/f1/f2_renamed/f3 (rel: /f1/f2/f3)
 
 /*
-   Initialization test for vospace Users table
+   Initialization test for vospace users table
 */
 
 INSERT INTO Users (rap_id, user_name, e_mail) VALUES ('3354', 'curban', 'cristiano.urban@inaf.it');
diff --git a/06-uws.sql b/06-uws.sql
index b3a72f4..147a063 100644
--- a/06-uws.sql
+++ b/06-uws.sql
@@ -1,12 +1,11 @@
-CREATE TYPE job_phase_enum AS ENUM ('PENDING', 'QUEUED', 'EXECUTING', 'ABORTED', 'COMPLETED', 'HELD', 'SUSPENDED', 'ERROR', 'ARCHIVED');
-
-CREATE TYPE job_type_enum AS ENUM ('pushToVoSpace', 'pullToVoSpace', 'pullFromVoSpace', 'pushFromVoSpace', 'moveNode', 'copyNode', 'other');
+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 TABLE job (
     job_id varchar not null,
     owner_id varchar not null,
-    job_type job_type_enum not null,
-    phase job_phase_enum not null,
+    job_type JobTypeEnum not null,
+    phase JobPhaseEnum not null,
     start_time timestamp,
     end_time timestamp,
     job_info jsonb,
-- 
GitLab