Skip to content

Commit

Permalink
A bit too zealous commenting out some db parts.
Browse files Browse the repository at this point in the history
That'll be done while merging
  • Loading branch information
Frédéric Haziza authored and Frédéric Haziza committed Jan 22, 2018
1 parent 362ccb1 commit 18723fc
Show file tree
Hide file tree
Showing 2 changed files with 82 additions and 7 deletions.
2 changes: 1 addition & 1 deletion docs/ingestion/db.rst
Original file line number Diff line number Diff line change
Expand Up @@ -7,7 +7,7 @@ schema is as follows.

.. literalinclude:: /../extras/db.sql
:language: sql
:lines: 5-7,14-31,50-56
:lines: 5-7,94-111,130-136

We do not use any Object-Relational Model (ORM, such as
SQLAlchemy). Instead, we simply implemented, in SQL, a few functions
Expand Down
87 changes: 81 additions & 6 deletions extras/db.sql
Original file line number Diff line number Diff line change
Expand Up @@ -8,12 +8,92 @@ CREATE TYPE hash_algo AS ENUM ('md5', 'sha256');
CREATE EXTENSION pgcrypto;


-- ##################################################
-- USERS
-- ##################################################
CREATE TABLE users (
id SERIAL, PRIMARY KEY(id), UNIQUE(id),
elixir_id TEXT NOT NULL, UNIQUE(elixir_id),
password_hash TEXT,
pubkey TEXT,
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT clock_timestamp(),
last_accessed TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT clock_timestamp(),
expiration INTERVAL NOT NULL,
CHECK (password_hash IS NOT NULL OR pubkey IS NOT NULL)
);

CREATE FUNCTION sanitize_id(elixir_id users.elixir_id%TYPE)
RETURNS users.elixir_id%TYPE AS $sanitize_id$
DECLARE
eid users.elixir_id%TYPE;
BEGIN
-- eid := trim(trailing '@elixir-europe.org' from elixir_id);
eid := regexp_replace(elixir_id, '@.*', '');
RETURN eid;
END;
$sanitize_id$ LANGUAGE plpgsql;

CREATE FUNCTION insert_user(elixir_id users.elixir_id%TYPE,
password_hash users.password_hash%TYPE,
public_key users.pubkey%TYPE,
exp_int users.expiration%TYPE DEFAULT INTERVAL '1' MONTH)

RETURNS users.id%TYPE AS $insert_user$
#variable_conflict use_column
DECLARE
user_id users.elixir_id%TYPE;
eid users.elixir_id%TYPE;
BEGIN
eid := sanitize_id(elixir_id);
INSERT INTO users (elixir_id,password_hash,pubkey,expiration) VALUES(eid,password_hash,public_key,exp_int)
ON CONFLICT (elixir_id) DO UPDATE SET last_accessed = DEFAULT, expiration = exp_int
RETURNING users.id INTO user_id;
RETURN user_id;
END;
$insert_user$ LANGUAGE plpgsql;

-- Delete other user entries that are too old
CREATE FUNCTION refresh_user(elixir_id users.elixir_id%TYPE)

RETURNS void AS $refresh_user$
#variable_conflict use_column
DECLARE
eid users.elixir_id%TYPE;
BEGIN
eid := sanitize_id(elixir_id);
UPDATE users SET last_accessed = DEFAULT WHERE elixir_id = eid;
RETURN;
END;
$refresh_user$ LANGUAGE plpgsql;

CREATE FUNCTION update_users()
RETURNS trigger AS $update_users$
BEGIN
DELETE FROM users WHERE last_accessed < current_timestamp - expiration;
RETURN NEW;
END;
$update_users$ LANGUAGE plpgsql;

CREATE TRIGGER delete_expired_users_trigger AFTER UPDATE ON users EXECUTE PROCEDURE update_users();

CREATE FUNCTION flush_user(elixir_id users.elixir_id%TYPE)
RETURNS void AS $flush_user$
#variable_conflict use_column
DECLARE
eid users.elixir_id%TYPE;
BEGIN
eid := sanitize_id(elixir_id);
DELETE FROM users WHERE elixir_id = eid; -- Future: and ega_user is true
RETURN;
END;
$flush_user$ LANGUAGE plpgsql;

-- ##################################################
-- FILES
-- ##################################################
CREATE TABLE files (
id SERIAL, PRIMARY KEY(id), UNIQUE (id),
elixir_id TEXT NOT NULL,
elixir_id TEXT REFERENCES users (elixir_id) ON DELETE CASCADE,
filename TEXT NOT NULL,
enc_checksum TEXT,
enc_checksum_algo hash_algo,
Expand Down Expand Up @@ -55,11 +135,6 @@ CREATE TABLE errors (
occured_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT clock_timestamp()
);

-- The reencryption field is used to store how the original unencrypted file was re-encrypted.
-- We gpg-decrypt the encrypted file and pipe the output to the re-encryptor.
-- The key size, the algorithm and the selected master key is recorded in the re-encrypted file (first line)
-- and in the database.

CREATE FUNCTION insert_error(file_id errors.file_id%TYPE,
msg errors.msg%TYPE,
from_user errors.from_user%TYPE)
Expand Down

0 comments on commit 18723fc

Please sign in to comment.