Select Git revision
00-tables.sql
00-tables.sql 6.38 KiB
/*
* This file is part of vospace-file-catalog
* Copyright (C) 2021 Istituto Nazionale di Astrofisica
* SPDX-License-Identifier: GPL-3.0-or-later
*/
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');
CREATE TABLE storage (
storage_id SMALLSERIAL NOT NULL,
storage_type StorageType NOT NULL,
base_path VARCHAR default NULL,
base_url VARCHAR default NULL,
hostname VARCHAR NOT NULL,
PRIMARY KEY (storage_id)
);
CREATE TABLE location (
location_id SMALLSERIAL NOT NULL,
location_type LocationType NOT NULL,
storage_src_id SMALLINT default NULL,
storage_dest_id SMALLINT default NULL,
PRIMARY KEY (location_id),
FOREIGN KEY (storage_src_id) REFERENCES storage (storage_id) ON DELETE CASCADE,
FOREIGN KEY (storage_dest_id) REFERENCES storage (storage_id)
);
CREATE TABLE node (
node_id BIGSERIAL NOT NULL,
parent_path LTREE default NULL,
parent_relative_path LTREE default NULL,
name VARCHAR NOT NULL,
os_name VARCHAR default NULL,
tstamp_wrapper_dir VARCHAR default NULL,
type NodeType NOT NULL,
location_id SMALLINT default NULL,
-- target URI for link nodes
target VARCHAR default NULL,
-- format is used to distinguish between unstuctured (format=NULL) and structured nodes having a well defined format
format VARCHAR default NULL,
-- async_trans tells us whether a node is hosted on a cold storage and has to be transferred asynchronously
async_trans BOOLEAN default false,
sticky BOOLEAN default false,
-- id of the blocking job running on the node (used to compute busy state)
job_id VARCHAR default NULL,
creator_id VARCHAR default NULL,
group_read VARCHAR[] default NULL,
group_write VARCHAR[] default NULL,
is_public BOOLEAN default NULL,
-- total container quota (in bytes)
quota BIGINT default NULL,
content_type VARCHAR default NULL,
content_encoding VARCHAR default NULL,
content_length BIGINT default NULL,
content_md5 TEXT default NULL,
created_on TIMESTAMP default CURRENT_TIMESTAMP,
last_modified TIMESTAMP default NULL,
accept_views TEXT[] default NULL,
provide_views TEXT[] default NULL,
protocols TEXT[] default NULL,
PRIMARY KEY (node_id),
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,
parent_path LTREE default NULL,
parent_relative_path LTREE default NULL,
name VARCHAR NOT NULL,
os_name VARCHAR default NULL,
tstamp_wrapper_dir VARCHAR default NULL,
type NodeType NOT NULL,
location_id SMALLINT default NULL,
-- target URI for link nodes
target VARCHAR default NULL,
-- format is used to distinguish between unstuctured (format=NULL) and structured nodes having a well defined format
format VARCHAR default NULL,
-- async_trans tells us whether a node is hosted on a cold storage and has to be transferred asynchronously
async_trans BOOLEAN default NULL,
sticky BOOLEAN default false,
job_id VARCHAR default NULL,
creator_id VARCHAR default NULL,
group_read VARCHAR[] default NULL,
group_write VARCHAR[] default NULL,
is_public BOOLEAN default NULL,
-- total container quota (in bytes)
quota BIGINT default NULL,
content_type VARCHAR default NULL,
content_encoding VARCHAR default NULL,
content_length BIGINT default NULL,
content_md5 TEXT default NULL,
created_on TIMESTAMP default NULL,
last_modified TIMESTAMP default NULL,
accept_views TEXT[] default NULL,
provide_views TEXT[] default NULL,
protocols TEXT[] default NULL,
-- add a deleted_on timestamp to keep track
deleted_on TIMESTAMP default CURRENT_TIMESTAMP,
phy_deleted_on TIMESTAMP default NULL,
PRIMARY KEY (node_id),
FOREIGN KEY (location_id) REFERENCES location (location_id)
);
CREATE TABLE users (
user_id VARCHAR NOT NULL,
user_name VARCHAR NOT NULL,
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,
-- store original transfer object (as sent by client)
job_info JSONB,
-- store result of transfer protocol negotiation
transfer_details JSONB,
-- list of nodes selected by the user via UI
node_list JSONB default NULL,
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);