From bf3be7d1292878e0b86c07d00991c8ffa4f70a27 Mon Sep 17 00:00:00 2001 From: Trivernis Date: Tue, 1 Oct 2019 15:02:07 +0200 Subject: [PATCH 1/2] changed sql - added create tables to anonymous block --- src/lib/QueryHelper.ts | 9 +++ src/lib/dataaccess/index.ts | 8 +- src/sql/create-tables.sql | 155 ++++++++++++++++++------------------ 3 files changed, 94 insertions(+), 78 deletions(-) diff --git a/src/lib/QueryHelper.ts b/src/lib/QueryHelper.ts index 01c98b8..1b8aa37 100644 --- a/src/lib/QueryHelper.ts +++ b/src/lib/QueryHelper.ts @@ -79,6 +79,15 @@ export class QueryHelper { this.pool = pgPool; } + /** + * Async init function + */ + public async init() { + await this.pool.connect(); + await this.createTables(); + await this.updateTableDefinitions(); + } + /** * creates all tables needed if a filepath was given with the constructor */ diff --git a/src/lib/dataaccess/index.ts b/src/lib/dataaccess/index.ts index 28ae27c..3dccfcd 100644 --- a/src/lib/dataaccess/index.ts +++ b/src/lib/dataaccess/index.ts @@ -42,8 +42,12 @@ namespace dataaccess { * Initializes everything that needs to be initialized asynchronous. */ export async function init() { - await queryHelper.createTables(); - await queryHelper.updateTableDefinitions(); + try { + await queryHelper.init(); + } catch (err) { + globals.logger.error(err.message); + globals.logger.debug(err.stack); + } } /** diff --git a/src/sql/create-tables.sql b/src/sql/create-tables.sql index e27559c..128492b 100644 --- a/src/sql/create-tables.sql +++ b/src/sql/create-tables.sql @@ -49,80 +49,83 @@ DO $$ BEGIN END$$; -- create tables +DO $$ BEGIN -CREATE TABLE IF NOT EXISTS "user_sessions" ( - "sid" varchar NOT NULL, - "sess" json NOT NULL, - "expire" timestamp(6) NOT NULL, - PRIMARY KEY ("sid") NOT DEFERRABLE INITIALLY IMMEDIATE -) WITH (OIDS=FALSE); - -CREATE TABLE IF NOT EXISTS users ( - id SERIAL PRIMARY KEY, - name varchar(128) NOT NULL, - handle varchar(128) UNIQUE NOT NULL, - password varchar(1024) NOT NULL, - email varchar(128) UNIQUE NOT NULL, - greenpoints INTEGER DEFAULT 0, - joined_at TIMESTAMP DEFAULT now() -); - -CREATE TABLE IF NOT EXISTS posts ( - id BIGSERIAL PRIMARY KEY, - upvotes INTEGER DEFAULT 0, - downvotes INTEGER DEFAULT 0, - created_at TIMESTAMP DEFAULT now(), - content text, - author SERIAL REFERENCES users (id) ON DELETE CASCADE, - type posttype NOT NULL DEFAULT 'MISC' -); - -CREATE TABLE IF NOT EXISTS votes ( - user_id SERIAL REFERENCES users (id) ON DELETE CASCADE, - item_id BIGSERIAL REFERENCES posts (id) ON DELETE CASCADE, - vote_type votetype DEFAULT 'DOWNVOTE', - PRIMARY KEY (user_id, item_id) -); - -CREATE TABLE IF NOT EXISTS events ( - id BIGSERIAL PRIMARY KEY, - time TIMESTAMP, - owner SERIAL REFERENCES users (id) -); - -CREATE TABLE IF NOT EXISTS event_members ( - event BIGSERIAL REFERENCES events (id), - member SERIAL REFERENCES users (id), - PRIMARY KEY (event, member) -); - -CREATE TABLE IF NOT EXISTS chats ( - id BIGSERIAL PRIMARY KEY -); - -CREATE TABLE IF NOT EXISTS chat_messages ( - chat BIGSERIAL REFERENCES chats (id) ON DELETE CASCADE, - author SERIAL REFERENCES users (id) ON DELETE SET NULL, - content VARCHAR(1024) NOT NULL, - created_at TIMESTAMP DEFAULT now(), - PRIMARY KEY (chat, author, created_at) -); - -CREATE TABLE IF NOT EXISTS chat_members ( - chat BIGSERIAL REFERENCES chats (id) ON DELETE CASCADE, - member SERIAL REFERENCES users (id) ON DELETE CASCADE, - PRIMARY KEY (chat, member) -); - -CREATE TABLE IF NOT EXISTS user_friends ( - user_id SERIAL REFERENCES users (id) ON DELETE CASCADE, - friend_id SERIAL REFERENCES users (id) ON DELETE CASCADE, - PRIMARY KEY (user_id, friend_id) -); - -CREATE TABLE IF NOT EXISTS requests ( - sender SERIAL REFERENCES users (id) ON DELETE CASCADE, - receiver SERIAL REFERENCES users (id) ON DELETE CASCADE, - type requesttype DEFAULT 'FRIENDREQUEST', - PRIMARY KEY (sender, receiver, type) -); + CREATE TABLE IF NOT EXISTS "user_sessions" ( + "sid" varchar NOT NULL, + "sess" json NOT NULL, + "expire" timestamp(6) NOT NULL, + PRIMARY KEY ("sid") NOT DEFERRABLE INITIALLY IMMEDIATE + ) WITH (OIDS=FALSE); + + CREATE TABLE IF NOT EXISTS users ( + id SERIAL PRIMARY KEY, + name varchar(128) NOT NULL, + handle varchar(128) UNIQUE NOT NULL, + password varchar(1024) NOT NULL, + email varchar(128) UNIQUE NOT NULL, + greenpoints INTEGER DEFAULT 0, + joined_at TIMESTAMP DEFAULT now() + ); + + CREATE TABLE IF NOT EXISTS posts ( + id BIGSERIAL PRIMARY KEY, + upvotes INTEGER DEFAULT 0, + downvotes INTEGER DEFAULT 0, + created_at TIMESTAMP DEFAULT now(), + content text, + author SERIAL REFERENCES users (id) ON DELETE CASCADE, + type posttype NOT NULL DEFAULT 'MISC' + ); + + CREATE TABLE IF NOT EXISTS votes ( + user_id SERIAL REFERENCES users (id) ON DELETE CASCADE, + item_id BIGSERIAL REFERENCES posts (id) ON DELETE CASCADE, + vote_type votetype DEFAULT 'DOWNVOTE', + PRIMARY KEY (user_id, item_id) + ); + + CREATE TABLE IF NOT EXISTS events ( + id BIGSERIAL PRIMARY KEY, + time TIMESTAMP, + owner SERIAL REFERENCES users (id) + ); + + CREATE TABLE IF NOT EXISTS event_members ( + event BIGSERIAL REFERENCES events (id), + member SERIAL REFERENCES users (id), + PRIMARY KEY (event, member) + ); + + CREATE TABLE IF NOT EXISTS chats ( + id BIGSERIAL PRIMARY KEY + ); + + CREATE TABLE IF NOT EXISTS chat_messages ( + chat BIGSERIAL REFERENCES chats (id) ON DELETE CASCADE, + author SERIAL REFERENCES users (id) ON DELETE SET NULL, + content VARCHAR(1024) NOT NULL, + created_at TIMESTAMP DEFAULT now(), + PRIMARY KEY (chat, author, created_at) + ); + + CREATE TABLE IF NOT EXISTS chat_members ( + chat BIGSERIAL REFERENCES chats (id) ON DELETE CASCADE, + member SERIAL REFERENCES users (id) ON DELETE CASCADE, + PRIMARY KEY (chat, member) + ); + + CREATE TABLE IF NOT EXISTS user_friends ( + user_id SERIAL REFERENCES users (id) ON DELETE CASCADE, + friend_id SERIAL REFERENCES users (id) ON DELETE CASCADE, + PRIMARY KEY (user_id, friend_id) + ); + + CREATE TABLE IF NOT EXISTS requests ( + sender SERIAL REFERENCES users (id) ON DELETE CASCADE, + receiver SERIAL REFERENCES users (id) ON DELETE CASCADE, + type requesttype DEFAULT 'FRIENDREQUEST', + PRIMARY KEY (sender, receiver, type) + ); + +END $$; From 2ed4f9793a67ab49156d4ac524e4f5a74b3098a0 Mon Sep 17 00:00:00 2001 From: Trivernis Date: Tue, 1 Oct 2019 15:13:36 +0200 Subject: [PATCH 2/2] Changed to table creation - changed creation and update to transaction type - fixed creation file --- src/lib/QueryHelper.ts | 26 ++++++++++++++++++++++++-- src/sql/create-tables.sql | 34 ++++++++++++++++++++-------------- 2 files changed, 44 insertions(+), 16 deletions(-) diff --git a/src/lib/QueryHelper.ts b/src/lib/QueryHelper.ts index 1b8aa37..83b36fc 100644 --- a/src/lib/QueryHelper.ts +++ b/src/lib/QueryHelper.ts @@ -95,7 +95,18 @@ export class QueryHelper { if (this.tableCreationFile) { logger.info("Creating nonexistent tables..."); const tableSql = await fsx.readFile(this.tableCreationFile, "utf-8"); - await this.query({text: tableSql}); + const trans = await this.createTransaction(); + await trans.begin(); + try { + await trans.query({text: tableSql}); + await trans.commit(); + } catch (err) { + globals.logger.error(`Error on table creation ${err.message}`); + globals.logger.debug(err.stack); + await trans.rollback(); + } finally { + trans.release(); + } } } @@ -106,7 +117,18 @@ export class QueryHelper { if (this.tableUpdateFile) { logger.info("Updating table definitions..."); const tableSql = await fsx.readFile(this.tableUpdateFile, "utf-8"); - await this.query({text: tableSql}); + const trans = await this.createTransaction(); + await trans.begin(); + try { + await trans.query({text: tableSql}); + await trans.commit(); + } catch (err) { + globals.logger.error(`Error on table update ${err.message}`); + globals.logger.debug(err.stack); + await trans.rollback(); + } finally { + trans.release(); + } } } diff --git a/src/sql/create-tables.sql b/src/sql/create-tables.sql index 128492b..70e49e2 100644 --- a/src/sql/create-tables.sql +++ b/src/sql/create-tables.sql @@ -15,20 +15,6 @@ DO $$BEGIN END $BODY$; END IF; - IF NOT function_exists('cast_to_votetype') THEN - CREATE FUNCTION cast_to_votetype(text) RETURNS votetype LANGUAGE plpgsql AS $BODY$ - BEGIN - RETURN CASE WHEN $1::votetype IS NULL THEN 'UPVOTE' ELSE $1::votetype END; - END $BODY$; - END IF; - - IF NOT function_exists('cast_to_posttype') THEN - CREATE FUNCTION cast_to_posttype(text) RETURNS posttype LANGUAGE plpgsql AS $BODY$ - BEGIN - RETURN CASE WHEN $1::posttype IS NULL THEN 'MISC' ELSE $1::posttype END; - END $BODY$; - END IF; - END$$; --create types @@ -48,6 +34,26 @@ DO $$ BEGIN END$$; +-- create functions relying on types + +DO $$ BEGIN + + IF NOT function_exists('cast_to_votetype') THEN + CREATE FUNCTION cast_to_votetype(text) RETURNS votetype LANGUAGE plpgsql AS $BODY$ + BEGIN + RETURN CASE WHEN $1::votetype IS NULL THEN 'UPVOTE' ELSE $1::votetype END; + END $BODY$; + END IF; + + IF NOT function_exists('cast_to_posttype') THEN + CREATE FUNCTION cast_to_posttype(text) RETURNS posttype LANGUAGE plpgsql AS $BODY$ + BEGIN + RETURN CASE WHEN $1::posttype IS NULL THEN 'MISC' ELSE $1::posttype END; + END $BODY$; + END IF; + +END$$; + -- create tables DO $$ BEGIN