somewhat functional postgre migration, pg_cron seems to not be working

This commit is contained in:
Ulysia 2025-01-06 19:21:44 +01:00
parent 5c106de4c1
commit ab61049de0
3 changed files with 82 additions and 54 deletions

View file

@ -1,8 +1,10 @@
--- ---
services: services:
bot: app:
container_name: hypixel-auc-notifier container_name: hypixel-auc-app
build: . build:
context: .
dockerfile: Dockerfile.bot
restart: unless-stopped restart: unless-stopped
depends_on: depends_on:
- db - db
@ -21,11 +23,16 @@ services:
db: db:
image: postgres:17.2 container_name: hypixel-auc-db
build:
context: .
dockerfile: Dockerfile.db
restart: always restart: always
environment: environment:
POSTGRES_PASSWORD: example # Change this to a secure password. Has to be identical to DB_PASSWORD in the bot service POSTGRES_PASSWORD: example # Change this to a secure password. Has to be identical to DB_PASSWORD in the bot service
POSTGRES_DB: hypixel POSTGRES_DB: hypixel
ports:
- 5432:5432
volumes: volumes:
- ./db_data:/var/lib/postgres/data - ./db_data:/var/lib/postgres/data
- /etc/localtime:/etc/localtime:ro - /etc/localtime:/etc/localtime:ro

View file

@ -25,64 +25,85 @@ class SqlSystem {
lbin DECIMAL(65,5), lbin DECIMAL(65,5),
UNIQUE (auctionid) 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 //Setup lifetime Trigger
await conn.query(` await conn.query(`
DELIMITER $$ -- Insert trigger function
CREATE TRIGGER IF NOT EXISTS insertLifetime CREATE OR REPLACE FUNCTION public.fn_insert_lifetime()
AFTER INSERT ON auctions RETURNS TRIGGER AS $$
FOR EACH ROW BEGIN
BEGIN INSERT INTO lifetimes (id, insertedon)
INSERT INTO lifetimes (id, insertedon) VALUES (NEW.id, NOW());
VALUES (NEW.ID, NOW()); RETURN NEW;
END$$ END;
DELIMITER ; $$ LANGUAGE plpgsql;
DELIMITER $$
CREATE TRIGGER IF NOT EXISTS updateLifetime -- Update trigger function
AFTER UPDATE ON auctions CREATE OR REPLACE FUNCTION public.fn_update_lifetime()
FOR EACH ROW RETURNS TRIGGER AS $$
BEGIN BEGIN
UPDATE lifetimes SET insertedon = NOW() WHERE id=NEW.ID; UPDATE lifetimes
END$$ SET insertedon = NOW()
DELIMITER ; WHERE id = NEW.id;
DELIMITER $$ RETURN NEW;
CREATE TRIGGER IF NOT EXISTS removeLifetime END;
BEFORE DELETE ON auctions $$ LANGUAGE plpgsql;
FOR EACH ROW
BEGIN -- Remove trigger function
DELETE FROM lifetimes WHERE id=OLD.ID; CREATE OR REPLACE FUNCTION public.fn_remove_lifetime()
END$$ RETURNS TRIGGER AS $$
DELIMITER ; 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 //Setup Table sanitation
await conn.query(` await conn.query(`
DELIMITER $$ CREATE OR REPLACE FUNCTION public.cleanup_old_entries()
CREATE PROCEDURE IF NOT EXISTS CleanupOldEntries() RETURNS void
LANGUAGE plpgsql
AS $$
DECLARE
temp_id INT;
BEGIN BEGIN
DECLARE done INT DEFAULT 0; FOR temp_id IN
DECLARE temp_id INT;
DECLARE cur CURSOR FOR
SELECT id SELECT id
FROM lifetimes FROM lifetimes
WHERE TIMESTAMPDIFF(HOUR, insertedon, NOW()) >= 6; WHERE EXTRACT(EPOCH FROM (NOW() - insertedon))/3600 >= 6 -- 6 hours
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = 1; LOOP
OPEN cur; -- Removes matching entries from auctions
read_loop: LOOP DELETE FROM auctions
FETCH cur INTO temp_id; WHERE auctions.id = temp_id;
IF done THEN
LEAVE read_loop;
END IF;
DELETE FROM auctions WHERE id = temp_id;
END LOOP; END LOOP;
CLOSE cur;
END$$ RETURN;
DELIMITER ; END;
SET GLOBAL event_scheduler = ON; $$;
CREATE EVENT IF NOT EXISTS CleanupOldEntriesEvent
ON SCHEDULE EVERY 2 MINUTE
DO
CALL CleanupOldEntries();
`); `);
} }
catch (error) { catch (error) {