From ab61049de08b00c7cf88620968bafc1c3914cb19 Mon Sep 17 00:00:00 2001 From: ulysia Date: Mon, 6 Jan 2025 19:21:44 +0100 Subject: [PATCH] somewhat functional postgre migration, pg_cron seems to not be working --- Dockerfile => Dockerfile.bot | 0 docker-compose.yml | 15 +++-- src/sqlFunctions.ts | 121 ++++++++++++++++++++--------------- 3 files changed, 82 insertions(+), 54 deletions(-) rename Dockerfile => Dockerfile.bot (100%) diff --git a/Dockerfile b/Dockerfile.bot similarity index 100% rename from Dockerfile rename to Dockerfile.bot diff --git a/docker-compose.yml b/docker-compose.yml index 29c9977..daceae5 100644 --- a/docker-compose.yml +++ b/docker-compose.yml @@ -1,8 +1,10 @@ --- services: - bot: - container_name: hypixel-auc-notifier - build: . + app: + container_name: hypixel-auc-app + build: + context: . + dockerfile: Dockerfile.bot restart: unless-stopped depends_on: - db @@ -21,11 +23,16 @@ services: db: - image: postgres:17.2 + container_name: hypixel-auc-db + build: + context: . + dockerfile: Dockerfile.db restart: always environment: POSTGRES_PASSWORD: example # Change this to a secure password. Has to be identical to DB_PASSWORD in the bot service POSTGRES_DB: hypixel + ports: + - 5432:5432 volumes: - ./db_data:/var/lib/postgres/data - /etc/localtime:/etc/localtime:ro diff --git a/src/sqlFunctions.ts b/src/sqlFunctions.ts index 7653a99..cf41a62 100644 --- a/src/sqlFunctions.ts +++ b/src/sqlFunctions.ts @@ -25,64 +25,85 @@ class SqlSystem { lbin DECIMAL(65,5), UNIQUE (auctionid) ); - CREATE TABLE if NOT EXISTS lifetimes (id UUID PRIMARY KEY, insertedon DATETIME(2)); + CREATE TABLE if NOT EXISTS lifetimes (id UUID PRIMARY KEY, insertedon TIMESTAMP(2)); `); //Setup lifetime Trigger await conn.query(` - DELIMITER $$ - CREATE TRIGGER IF NOT EXISTS insertLifetime - AFTER INSERT ON auctions - FOR EACH ROW - BEGIN - INSERT INTO lifetimes (id, insertedon) - VALUES (NEW.ID, NOW()); - END$$ - DELIMITER ; - DELIMITER $$ - CREATE TRIGGER IF NOT EXISTS updateLifetime - AFTER UPDATE ON auctions - FOR EACH ROW - BEGIN - UPDATE lifetimes SET insertedon = NOW() WHERE id=NEW.ID; - END$$ - DELIMITER ; - DELIMITER $$ - CREATE TRIGGER IF NOT EXISTS removeLifetime - BEFORE DELETE ON auctions - FOR EACH ROW - BEGIN - DELETE FROM lifetimes WHERE id=OLD.ID; - END$$ - DELIMITER ; + -- Insert trigger function + CREATE OR REPLACE FUNCTION public.fn_insert_lifetime() + RETURNS TRIGGER AS $$ + BEGIN + INSERT INTO lifetimes (id, insertedon) + VALUES (NEW.id, NOW()); + RETURN NEW; + END; + $$ LANGUAGE plpgsql; + + -- Update trigger function + CREATE OR REPLACE FUNCTION public.fn_update_lifetime() + RETURNS TRIGGER AS $$ + BEGIN + UPDATE lifetimes + SET insertedon = NOW() + WHERE id = NEW.id; + RETURN NEW; + END; + $$ LANGUAGE plpgsql; + + -- Remove trigger function + CREATE OR REPLACE FUNCTION public.fn_remove_lifetime() + RETURNS TRIGGER AS $$ + BEGIN + DELETE FROM lifetimes + WHERE id = OLD.id; + RETURN OLD; + END; + $$ LANGUAGE plpgsql; `); + await conn.query(` + -- Insert trigger + DROP TRIGGER IF EXISTS insert_lifetime ON auctions; + CREATE TRIGGER insert_lifetime + AFTER INSERT ON auctions + FOR EACH ROW + EXECUTE PROCEDURE public.fn_insert_lifetime(); + + -- Update trigger + DROP TRIGGER IF EXISTS update_lifetime ON auctions; + CREATE TRIGGER update_lifetime + AFTER UPDATE ON auctions + FOR EACH ROW + EXECUTE PROCEDURE public.fn_update_lifetime(); + + -- Remove trigger + DROP TRIGGER IF EXISTS remove_lifetime ON auctions; + CREATE TRIGGER remove_lifetime + BEFORE DELETE ON auctions + FOR EACH ROW + EXECUTE PROCEDURE public.fn_remove_lifetime(); + `); //Setup Table sanitation await conn.query(` - DELIMITER $$ - CREATE PROCEDURE IF NOT EXISTS CleanupOldEntries() + CREATE OR REPLACE FUNCTION public.cleanup_old_entries() + RETURNS void + LANGUAGE plpgsql + AS $$ + DECLARE + temp_id INT; BEGIN - DECLARE done INT DEFAULT 0; - DECLARE temp_id INT; - DECLARE cur CURSOR FOR - SELECT id - FROM lifetimes - WHERE TIMESTAMPDIFF(HOUR, insertedon, NOW()) >= 6; - DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = 1; - OPEN cur; - read_loop: LOOP - FETCH cur INTO temp_id; - IF done THEN - LEAVE read_loop; - END IF; - DELETE FROM auctions WHERE id = temp_id; + FOR temp_id IN + SELECT id + FROM lifetimes + WHERE EXTRACT(EPOCH FROM (NOW() - insertedon))/3600 >= 6 -- 6 hours + LOOP + -- Removes matching entries from auctions + DELETE FROM auctions + WHERE auctions.id = temp_id; END LOOP; - CLOSE cur; - END$$ - DELIMITER ; - SET GLOBAL event_scheduler = ON; - CREATE EVENT IF NOT EXISTS CleanupOldEntriesEvent - ON SCHEDULE EVERY 2 MINUTE - DO - CALL CleanupOldEntries(); + + RETURN; + END; + $$; `); } catch (error) {