From d3e19bddfe6aeec5bc22ed4182450896a6b575a9 Mon Sep 17 00:00:00 2001 From: Reid 'arrdem' McKenzie Date: Sat, 8 Jul 2023 13:14:04 -0600 Subject: [PATCH] Break up the schema file --- projects/tentacles/BUILD | 2 +- .../src/python/tentacles/__main__.py | 1 + projects/tentacles/src/python/tentacles/db.py | 17 +- .../tentacles/src/python/tentacles/schema.sql | 784 ------------------ .../src/python/tentacles/sql/__init__.py | 1 + .../src/python/tentacles/sql/emails.sql | 45 + .../src/python/tentacles/sql/files.sql | 47 ++ .../src/python/tentacles/sql/jobs.sql | 180 ++++ .../src/python/tentacles/sql/migrations.sql | 26 + .../src/python/tentacles/sql/printers.sql | 165 ++++ .../src/python/tentacles/sql/user_keys.sql | 92 ++ .../python/tentacles/sql/user_statuses.sql | 8 + .../src/python/tentacles/sql/users.sql | 135 +++ .../tentacles/src/python/tentacles/workers.py | 10 +- 14 files changed, 723 insertions(+), 790 deletions(-) delete mode 100644 projects/tentacles/src/python/tentacles/schema.sql create mode 100644 projects/tentacles/src/python/tentacles/sql/__init__.py create mode 100644 projects/tentacles/src/python/tentacles/sql/emails.sql create mode 100644 projects/tentacles/src/python/tentacles/sql/files.sql create mode 100644 projects/tentacles/src/python/tentacles/sql/jobs.sql create mode 100644 projects/tentacles/src/python/tentacles/sql/migrations.sql create mode 100644 projects/tentacles/src/python/tentacles/sql/printers.sql create mode 100644 projects/tentacles/src/python/tentacles/sql/user_keys.sql create mode 100644 projects/tentacles/src/python/tentacles/sql/user_statuses.sql create mode 100644 projects/tentacles/src/python/tentacles/sql/users.sql diff --git a/projects/tentacles/BUILD b/projects/tentacles/BUILD index eb0a078..349c659 100644 --- a/projects/tentacles/BUILD +++ b/projects/tentacles/BUILD @@ -1,6 +1,6 @@ py_project( name = "tentacles", - shebang = "/usr/bin/env python3.11", + shebang = "/usr/bin/env python3", zip_safe = False, main = "src/python/tentacles/__main__.py", main_deps = [ diff --git a/projects/tentacles/src/python/tentacles/__main__.py b/projects/tentacles/src/python/tentacles/__main__.py index c7fb82c..fca1a97 100644 --- a/projects/tentacles/src/python/tentacles/__main__.py +++ b/projects/tentacles/src/python/tentacles/__main__.py @@ -148,6 +148,7 @@ def serve(hostname: str, port: int, config: Path, trace: bool): Worker(cherrypy.engine, app, db_factory, revoke_jobs, frequency=5).start() Worker(cherrypy.engine, app, db_factory, pull_jobs, frequency=5).start() Worker(cherrypy.engine, app, db_factory, send_emails, frequency=5).start() + Worker(cherrypy.engine, app, db_factory, debug_queue, frequency=5).start() # Run the server cherrypy.engine.start() diff --git a/projects/tentacles/src/python/tentacles/db.py b/projects/tentacles/src/python/tentacles/db.py index 30f4547..237c2f4 100644 --- a/projects/tentacles/src/python/tentacles/db.py +++ b/projects/tentacles/src/python/tentacles/db.py @@ -12,11 +12,20 @@ from time import sleep from types import GeneratorType, new_class from typing import Optional -import aiosql +from aiosql.aiosql import _make_driver_adapter as get_adapter +from aiosql.query_loader import QueryLoader +from aiosql.queries import Queries - -with files(__package__).joinpath("schema.sql").open("r") as fp: - _queries = aiosql.from_str(fp.read(), "sqlite3") +_sqlite = get_adapter("sqlite3") +_loader = QueryLoader(_sqlite, None) +_queries = Queries(_sqlite) +for f in files("tentacles.sql").iterdir(): + if f.is_file() and f.name.endswith(".sql"): + print("Loading", f) + with f.open() as fp: + _queries.load_from_list( + _loader.load_query_data_from_sql(fp.read(), fname=f) + ) log = logging.getLogger(__name__) diff --git a/projects/tentacles/src/python/tentacles/schema.sql b/projects/tentacles/src/python/tentacles/schema.sql deleted file mode 100644 index e5c1561..0000000 --- a/projects/tentacles/src/python/tentacles/schema.sql +++ /dev/null @@ -1,784 +0,0 @@ --- name: migration-0000-create_migrations -CREATE TABLE IF NOT EXISTS migrations ( - id INTEGER PRIMARY KEY AUTOINCREMENT - , name TEXT - , fingerprint TEXT - , executed_at TEXT DEFAULT (datetime('now')) - , UNIQUE(name) -); - --- name: list-migrations -SELECT - * -FROM migrations -ORDER BY - datetime(executed_at) ASC -; - --- name: record-migration! -INSERT INTO migrations ( - name - , fingerprint -) -VALUES ( - :name - , :fingerprint -); - --- name: migration-0001-create_tables# --- Initialize the core db tables. Arguably migration 0. ----------------------------------------------------------------------------------------------------- --- User structures -CREATE TABLE IF NOT EXISTS groups ( - id INTEGER PRIMARY KEY AUTOINCREMENT - , name TEXT - , priority INTEGER CHECK(priority IS NOT NULL AND priority > 0) -); - -INSERT OR IGNORE INTO groups (id, name, priority) VALUES (0, 'root', 20); -INSERT OR IGNORE INTO groups (id, name, priority) VALUES (1, 'users', 10); -INSERT OR IGNORE INTO groups (id, name, priority) VALUES (2, 'guests', 0); - -CREATE TABLE IF NOT EXISTS user_statuses ( - id INTEGER PRIMARY KEY AUTOINCREMENT - , name TEXT - , UNIQUE(name) -); - -INSERT OR IGNORE INTO user_statuses (id, name) VALUES (-4, 'passwdchng'); -INSERT OR IGNORE INTO user_statuses (id, name) VALUES (-3, 'unverified'); -INSERT OR IGNORE INTO user_statuses (id, name) VALUES (-2, 'unapproved'); -INSERT OR IGNORE INTO user_statuses (id, name) VALUES (-1, 'disabled'); -INSERT OR IGNORE INTO user_statuses (id, name) VALUES (1, 'enabled'); - -CREATE TABLE IF NOT EXISTS users ( - id INTEGER PRIMARY KEY AUTOINCREMENT - , group_id INTEGER - , name TEXT - , email TEXT - , hash TEXT - , status_id INTEGER - , created_at TEXT DEFAULT (datetime('now')) - , verification_token TEXT DEFAULT (lower(hex(randomblob(32)))) - , verified_at TEXT - , approved_at TEXT - , enabled_at TEXT - , FOREIGN KEY(group_id) REFERENCES groups(id) - , FOREIGN KEY(status_id) REFERENCES user_statuses(id) - , UNIQUE(name) - , UNIQUE(email) -); - ----------------------------------------------------------------------------------------------------- --- Keys represent API keys and auth sessions -CREATE TABLE IF NOT EXISTS user_keys ( - id TEXT PRIMARY KEY DEFAULT (lower(hex(randomblob(32)))) - , user_id INTEGER - , name TEXT - , expiration TEXT -); - ----------------------------------------------------------------------------------------------------- --- Printers represent physical devices (really octoprint API targets) that jobs can go to -CREATE TABLE IF NOT EXISTS printer_statuses ( - id INTEGER PRIMARY KEY AUTOINCREMENT - , name TEXT - , UNIQUE(name) -); - -INSERT OR IGNORE INTO printer_statuses (id, name) VALUES (-1, 'error'); -INSERT OR IGNORE INTO printer_statuses (id, name) VALUES (0, 'disconnected'); -INSERT OR IGNORE INTO printer_statuses (id, name) VALUES (2, 'connecting'); -INSERT OR IGNORE INTO printer_statuses (id, name) VALUES (2, 'connected'); -INSERT OR IGNORE INTO printer_statuses (id, name) VALUES (3, 'idle'); -INSERT OR IGNORE INTO printer_statuses (id, name) VALUES (4, 'running'); - -CREATE TABLE IF NOT EXISTS printers ( - id INTEGER PRIMARY KEY AUTOINCREMENT - , name TEXT - , url TEXT - , stream_url TEXT - , api_key TEXT - , status_id INTEGER - , last_poll_date TEXT - , FOREIGN KEY(status_id) REFERENCES printer_statuses(id) -); - ----------------------------------------------------------------------------------------------------- --- Files are printables -CREATE TABLE IF NOT EXISTS files ( - id INTEGER PRIMARY KEY AUTOINCREMENT - , user_id INTEGER - , filename TEXT - , path TEXT - , upload_date TEXT - , FOREIGN KEY(user_id) REFERENCES user(id) -); - ----------------------------------------------------------------------------------------------------- --- A job is a request for a copy of a file to be run off --- For simplicity, jobs also serve as scheduling records - -CREATE TABLE IF NOT EXISTS job_statuses ( - id INTEGER PRIMARY KEY AUTOINCREMENT - , name TEXT - , UNIQUE(name) -); - -INSERT OR IGNORE INTO job_statuses (id, name) VALUES (2, 'success'); -INSERT OR IGNORE INTO job_statuses (id, name) VALUES (1, 'running'); -INSERT OR IGNORE INTO job_statuses (id, name) VALUES (0, 'queued'); -INSERT OR IGNORE INTO job_statuses (id, name) VALUES (-1, 'cancelled'); -INSERT OR IGNORE INTO job_statuses (id, name) VALUES (-2, 'failed'); - -CREATE TABLE IF NOT EXISTS jobs ( - id INTEGER PRIMARY KEY AUTOINCREMENT - , user_id INTEGER NOT NULL - , file_id INTEGER NOT NULL - , printer_id INTEGER - , started_at TEXT - , cancelled_at TEXT - , finished_at TEXT - , status_id INTEGER DEFAULT (0) - , message TEXT - , FOREIGN KEY(user_id) REFERENCES users(id) - , FOREIGN KEY(file_id) REFERENCES files(id) - , FOREIGN KEY(printer_id) REFERENCES printer(id) -); - ----------------------------------------------------------------------------------------------------- --- Emails are used for notifications -CREATE TABLE IF NOT EXISTS email_spool ( - id INTEGER PRIMARY KEY AUTOINCREMENT - , user_id INTEGER NOT NULL - , subject TEXT - , body TEXT - , sent_at TEXT - , FOREIGN KEY(user_id) REFERENCES users(id) -); - --- name: migration-0002-create-occupied-state# --- Create a state representing that the printer needs to be unloaded after a print -INSERT OR IGNORE INTO printer_statuses (id, name) VALUES (5, 'occupied'); - --- name: migration-0003-create-printer-chassis# -CREATE TABLE IF NOT EXISTS chassis ( - id INTEGER PRIMARY KEY AUTOINCREMENT - , name TEXT - , limit_x INTEGER - , limit_y INTEGER - , limit_z INTEGER - , limit_bed INTEGER - , limit_hotend INTEGER - , limit_tools INTEGER -); - -INSERT INTO chassis ( - id - , name - , limit_x - , limit_y - , limit_z - , limit_bed - , limit_hotend - , limit_tools -) VALUES ( - 0 - , 'Creality CR-10v3' - , 300 - , 300 - , 400 - , 100 - , 260 - , 1 -); - -ALTER TABLE printers ADD chassis_id INTEGER REFERENCES chassis(id) DEFAULT 1; - ---- name: migration-0004-create-printer-filament# -CREATE TABLE IF NOT EXISTS filament ( - id INTEGER PRIMARY KEY AUTOINCREMENT - , name TEXT - , UNIQUE(name) -); - -INSERT OR IGNORE INTO filament (name) VALUES ('pla'); -INSERT OR IGNORE INTO filament (name) VALUES ('abs'); -INSERT OR IGNORE INTO filament (name) VALUES ('petg'); - -ALTER TABLE printers ADD filament_id INTEGER REFERENCES filament(id) DEFAULT 1; - --- name: migration-0005-create-printer-properties# -ALTER TABLE printers ADD enabled BOOLEAN default true; -ALTER TABLE printers ADD nozzle_diameter INTEGER default 4; - --- name: migration-0006-prusa-mini# -INSERT INTO chassis ( - id - , name - , limit_x - , limit_y - , limit_z - , limit_bed - , limit_hotend - , limit_tools -) VALUES ( - 1 - , 'Prusa Mini' - , 180 - , 180 - , 180 - , 100 - , 280 - , 1 -); - --- name: migration-0007-prusa-i3# -INSERT INTO chassis ( - id - , name - , limit_x - , limit_y - , limit_z - , limit_bed - , limit_hotend - , limit_tools -) VALUES ( - 2 - , 'Prusa i3' - , 250 - , 210 - , 210 - , 120 - , 300 - , 1 -); - --- name: migration-0008-prusa-xl# -INSERT INTO chassis ( - id - , name - , limit_x - , limit_y - , limit_z - , limit_bed - , limit_hotend - , limit_tools -) VALUES ( - 3 - , 'Prusa XL' - , 360 - , 360 - , 360 - , 120 - , 300 - , 5 -); - ----------------------------------------------------------------------------------------------------- --- Users ----------------------------------------------------------------------------------------------------- - --- name: try-create-user^ -INSERT INTO users ( - name - , email - , hash - , group_id - , status_id -) -VALUES (:name, :email, :hash, :gid, :sid) -RETURNING * -; - --- name: fetch_user^ -SELECT - * -FROM users -WHERE - id = :uid -; - --- name: list-users -SELECT - * -FROM users -; - --- name: list-unverified-users -SELECT - * -FROM users -WHERE - status_id = -2 - AND verified_at IS NULL -; - --- name: try-verify-user^ -UPDATE users -SET - verified_at = datetime('now') - , verification_token = lower(hex(randomblob(32))) -WHERE - verification_token = :token -RETURNING - id - , name -; - --- name: enable-user^ -UPDATE users -SET - enabled_at = datetime('now') -WHERE - id = :uid -RETURNING - id - , name -; - --- name: disable-user^ -UPDATE users -SET - enabled_at = NULL -WHERE - id = :uid -RETURNING - id - , name -; - --- name: approve-user^ -UPDATE users -SET - approved_at = datetime('now') -WHERE - id = :uid -RETURNING - id - , name -; - --- name: set-user-status^ -UPDATE users -SET - status_id = (SELECT id FROM user_statuses WHERE id = :status OR name = :status) -WHERE - id = :uid -RETURNING - id - , name -; - ----------------------------------------------------------------------------------------------------- --- User statuses ----------------------------------------------------------------------------------------------------- - --- name: fetch-user-status^ -SELECT - id - , name -FROM user_statuses -WHERE - id = :uid -; - ----------------------------------------------------------------------------------------------------- --- Sessions / 'keys' ----------------------------------------------------------------------------------------------------- - --- name: create-key^ -INSERT INTO user_keys ( - user_id - , name - , expiration -) -VALUES (:uid, :name, :expiration) -RETURNING - id - , user_id -; - --- name: try-login^ -SELECT - id - , status_id -FROM users -WHERE - ((name = :username AND hash = :hash) - OR (email = :username AND hash = :hash)) - AND ((verified_at IS NOT NULL - AND approved_at IS NOT NULL - AND enabled_at IS NOT NULL) - OR group_id = 0) -LIMIT 1 -; - --- name: list-keys -SELECT - id - , name - , expiration -FROM user_keys -WHERE - user_id = :uid -; - --- name: list-nonweb-keys -SELECT - id - , name - , expiration -FROM user_keys -WHERE - user_id = :uid - AND name NOT LIKE '%web session%' -; - --- name: fetch-key^ -SELECT - * -FROM user_keys -WHERE - id = :kid -; - --- name: try-key^ -SELECT - k.id - , user_id -FROM user_keys k -INNER JOIN users u - ON k.user_id = u.id -WHERE - (expiration IS NULL OR unixepoch(expiration) > unixepoch('now')) - AND k.id = :kid - AND u.enabled_at IS NOT NULL -- and the user is not disabled! -; - --- name: refresh-key -UPDATE user_keys -SET - expiration = :expiration -WHERE - id = :kid -; - --- name: delete-key -DELETE FROM user_keys -WHERE - user_id = :uid - AND id = :kid -; - ----------------------------------------------------------------------------------------------------- --- Printers ----------------------------------------------------------------------------------------------------- - --- name: try-create-printer^ -INSERT INTO printers ( - name - , url - , api_key - , status_id -) -VALUES (:name, :url, :api_key, :sid) -RETURNING - id -; - --- name: fetch-printer^ -SELECT - p.id - , p.name - , p.url - , p.stream_url - , p.api_key - , p.last_poll_date - , s.name as status -FROM printers p -INNER JOIN printer_statuses s ON p.status_id = s.id -WHERE p.id = :pid -; - --- name: list-printers -SELECT - p.id - , p.name - , p.url - , p.stream_url - , p.api_key - , p.last_poll_date - , s.name as status -FROM printers p -INNER JOIN printer_statuses s ON p.status_id = s.id -; - --- name: list-idle-printers -SELECT p.id -FROM printers p -LEFT JOIN (SELECT id, printer_id FROM jobs WHERE finished_at IS NULL) j - ON p.id = j.printer_id -INNER JOIN printer_statuses s - ON p.status_id = s.id -WHERE - j.id IS NULL - AND s.name = 'idle' -; - --- name: update-printer-status! -UPDATE printers -SET - status_id = (SELECT id FROM printer_statuses WHERE name = :status or id = :status) - , last_poll_date = datetime('now') -WHERE - id = :pid -; - --- name: edit-printer -UPDATE printers -SET - name = :name - , url = :url - , stream_url = :stream_url - , api_key = :api_key - , filament_load = :filament_load - , enabled = (CASE WHEN LOWER(:enabled) = 'true' THEN 1 ELSE 0) -WHERE - id = :id -; - ----------------------------------------------------------------------------------------------------- --- Files ----------------------------------------------------------------------------------------------------- - --- name: create-file^ -INSERT INTO files ( - user_id - , filename - , path - , upload_date -) -VALUES (:uid, :filename, :path , datetime('now')) -RETURNING - id -; - --- name: list-files -SELECT - * - , (SELECT COUNT(*) FROM jobs WHERE file_id = f.id AND status_id > 1) AS `print_successes` - , (SELECT COUNT(*) FROM jobs WHERE file_id = f.id AND status_id < 0) AS `print_failures` -FROM files f -WHERE - user_id = :uid -; - --- name: delete-file! -DELETE FROM files -WHERE - user_id = :uid - AND id = :fid -; - --- name: fetch-file^ -SELECT - * -FROM files -WHERE - user_id = :uid - AND id = :fid -; - ----------------------------------------------------------------------------------------------------- --- Jobs ----------------------------------------------------------------------------------------------------- - --- name: create-job^ -INSERT INTO jobs ( - user_id - , file_id -) -VALUES ( - :uid - , :fid -) -RETURNING - id -; --- name: fetch-job^ -SELECT - * -FROM jobs -WHERE - user_id = :uid - AND id = :jid -; - --- name: list-jobs -SELECT - * - , (SELECT name FROM job_statuses WHERE id = j.status_id) AS `status` -FROM jobs -WHERE - (:uid IS NULL OR user_id = :uid) -; - --- name: list-jobs-by-file -SELECT - * - , (SELECT name FROM job_statuses WHERE id = j.status_id) AS `status` -FROM jobs -WHERE - file_id = :fid - , uid = :uid -; - --- name: list-job-queue -SELECT - * -FROM jobs -WHERE - finished_at IS NULL - AND (:uid IS NULL OR user_id = :uid) -; - --- name: poll-job-queue^ -SELECT - * -FROM jobs -WHERE - started_at IS NULL - AND finished_at IS NULL - AND printer_id IS NULL -LIMIT 1 -; - --- name: list-job-history -SELECT - * - , (SELECT name FROM job_statuses WHERE id = j.status_id) AS `status` -FROM jobs j -WHERE - finished_at IS NOT NULL - AND (:uid IS NULL OR user_id = :uid) -ORDER BY - datetime(finished_at) DESC -LIMIT 25 -; - --- name: list-mapped-jobs -SELECT - * -FROM jobs -WHERE - started_at IS NULL - AND printer_id IS NOT NULL -; - --- name: list-running-jobs -SELECT - * -FROM jobs -WHERE - started_at IS NOT NULL - AND printer_id IS NOT NULL - AND finished_at IS NULL -; - --- name: list-canceling-jobs -SELECT - * -FROM jobs -WHERE - finished_at IS NULL - AND cancelled_at IS NOT NULL -; - --- name: fetch-job-by-printer^ -SELECT - * -FROM jobs -WHERE - printer_id = :pid - AND finished_at IS NULL -; - --- name: assign-job! -UPDATE jobs -SET - printer_id = :pid -WHERE - id = :jid -; - --- name: start-job! -UPDATE jobs -SET - started_at = datetime('now') -WHERE - id = :jid -; - --- name: cancel-job! -UPDATE jobs -SET - cancelled_at = datetime('now') -WHERE - user_id = :uid - AND id = :jid -; - --- name: finish-job! -UPDATE jobs -SET - finished_at = datetime('now') - , status_id = (SELECT id FROM job_statuses WHERE name = :state) - , message = :message -WHERE - id = :jid - AND finished_at IS NULL -- guard against calling this twice -; - --- name: delete-job! -DELETE FROM jobs -WHERE - user_id = :uid - AND id = :jid -; - --- name: create-email! -INSERT INTO email_spool ( - user_id - , subject - , body -) VALUES ( - :uid - , :subject - , :body -) -RETURNING - id -; - --- name: send-email! -UPDATE email_spool -SET - sent_at = datetime('now') -WHERE - id = :eid -; - --- name: poll-email-queue -SELECT - s.id as `id` - , u.email as `to` - , subject - , body -FROM email_spool s -INNER JOIN users u - ON s.user_id = u.id -WHERE - s.sent_at IS NULL -LIMIT 1 -; diff --git a/projects/tentacles/src/python/tentacles/sql/__init__.py b/projects/tentacles/src/python/tentacles/sql/__init__.py new file mode 100644 index 0000000..e5a0d9b --- /dev/null +++ b/projects/tentacles/src/python/tentacles/sql/__init__.py @@ -0,0 +1 @@ +#!/usr/bin/env python3 diff --git a/projects/tentacles/src/python/tentacles/sql/emails.sql b/projects/tentacles/src/python/tentacles/sql/emails.sql new file mode 100644 index 0000000..553c165 --- /dev/null +++ b/projects/tentacles/src/python/tentacles/sql/emails.sql @@ -0,0 +1,45 @@ +-- name: migration-0000-create-email-spool# +CREATE TABLE IF NOT EXISTS email_spool ( + id INTEGER PRIMARY KEY AUTOINCREMENT + , user_id INTEGER NOT NULL + , subject TEXT + , body TEXT + , sent_at TEXT + , FOREIGN KEY(user_id) REFERENCES users(id) +); + +-- name: create-email! +INSERT INTO email_spool ( + user_id + , subject + , body +) VALUES ( + :uid + , :subject + , :body +) +RETURNING + id +; + +-- name: send-email! +UPDATE email_spool +SET + sent_at = datetime('now') +WHERE + id = :eid +; + +-- name: poll-email-queue +SELECT + s.id as `id` + , u.email as `to` + , subject + , body +FROM email_spool s +INNER JOIN users u + ON s.user_id = u.id +WHERE + s.sent_at IS NULL +LIMIT 1 +; diff --git a/projects/tentacles/src/python/tentacles/sql/files.sql b/projects/tentacles/src/python/tentacles/sql/files.sql new file mode 100644 index 0000000..9b2760e --- /dev/null +++ b/projects/tentacles/src/python/tentacles/sql/files.sql @@ -0,0 +1,47 @@ +-- name: migration-0000-create-files# +CREATE TABLE IF NOT EXISTS files ( + id INTEGER PRIMARY KEY AUTOINCREMENT + , user_id INTEGER + , filename TEXT + , path TEXT + , upload_date TEXT + , FOREIGN KEY(user_id) REFERENCES user(id) +); + +-- name: create-file^ +INSERT INTO files ( + user_id + , filename + , path + , upload_date +) +VALUES (:uid, :filename, :path , datetime('now')) +RETURNING + id +; + +-- name: list-files +SELECT + * + , (SELECT COUNT(*) FROM jobs WHERE file_id = f.id AND status_id > 1) AS `print_successes` + , (SELECT COUNT(*) FROM jobs WHERE file_id = f.id AND status_id < 0) AS `print_failures` +FROM files f +WHERE + user_id = :uid +; + +-- name: delete-file! +DELETE FROM files +WHERE + user_id = :uid + AND id = :fid +; + +-- name: fetch-file^ +SELECT + * +FROM files +WHERE + user_id = :uid + AND id = :fid +; diff --git a/projects/tentacles/src/python/tentacles/sql/jobs.sql b/projects/tentacles/src/python/tentacles/sql/jobs.sql new file mode 100644 index 0000000..f1eaf7e --- /dev/null +++ b/projects/tentacles/src/python/tentacles/sql/jobs.sql @@ -0,0 +1,180 @@ +-- name: migration-0000-create-jobs# +CREATE TABLE IF NOT EXISTS job_statuses ( + id INTEGER PRIMARY KEY AUTOINCREMENT + , name TEXT + , UNIQUE(name) +); + +INSERT OR IGNORE INTO job_statuses (id, name) VALUES (2, 'success'); +INSERT OR IGNORE INTO job_statuses (id, name) VALUES (1, 'running'); +INSERT OR IGNORE INTO job_statuses (id, name) VALUES (0, 'queued'); +INSERT OR IGNORE INTO job_statuses (id, name) VALUES (-1, 'cancelled'); +INSERT OR IGNORE INTO job_statuses (id, name) VALUES (-2, 'failed'); + +CREATE TABLE IF NOT EXISTS jobs ( + id INTEGER PRIMARY KEY AUTOINCREMENT + , user_id INTEGER NOT NULL + , file_id INTEGER NOT NULL + , printer_id INTEGER + , started_at TEXT + , cancelled_at TEXT + , finished_at TEXT + , status_id INTEGER DEFAULT (0) + , message TEXT + , FOREIGN KEY(user_id) REFERENCES users(id) + , FOREIGN KEY(file_id) REFERENCES files(id) + , FOREIGN KEY(printer_id) REFERENCES printer(id) +); + +-- name: create-job^ +INSERT INTO jobs ( + user_id + , file_id +) +VALUES ( + :uid + , :fid +) +RETURNING + id +; +-- name: fetch-job^ +SELECT + * +FROM jobs +WHERE + user_id = :uid + AND id = :jid +; + +-- name: list-jobs +SELECT + * + , (SELECT name FROM job_statuses WHERE id = j.status_id) AS `status` +FROM jobs +WHERE + (:uid IS NULL OR user_id = :uid) +; + +-- name: list-jobs-by-file +SELECT + * + , (SELECT name FROM job_statuses WHERE id = j.status_id) AS `status` +FROM jobs +WHERE + file_id = :fid + , uid = :uid +; + +-- name: list-job-queue +SELECT + * +FROM jobs +WHERE + finished_at IS NULL + AND (:uid IS NULL OR user_id = :uid) +; + +-- name: poll-job-queue^ +SELECT + * +FROM jobs +WHERE + started_at IS NULL + AND finished_at IS NULL + AND printer_id IS NULL +LIMIT 1 +; + +-- name: list-job-history +SELECT + * + , (SELECT name FROM job_statuses WHERE id = j.status_id) AS `status` +FROM jobs j +WHERE + finished_at IS NOT NULL + AND (:uid IS NULL OR user_id = :uid) +ORDER BY + datetime(finished_at) DESC +LIMIT 25 +; + +-- name: list-mapped-jobs +SELECT + * +FROM jobs +WHERE + started_at IS NULL + AND printer_id IS NOT NULL +; + +-- name: list-running-jobs +SELECT + * +FROM jobs +WHERE + started_at IS NOT NULL + AND printer_id IS NOT NULL + AND finished_at IS NULL +; + +-- name: list-canceling-jobs +SELECT + * +FROM jobs +WHERE + finished_at IS NULL + AND cancelled_at IS NOT NULL +; + +-- name: fetch-job-by-printer^ +SELECT + * +FROM jobs +WHERE + printer_id = :pid + AND finished_at IS NULL +; + +-- name: assign-job! +UPDATE jobs +SET + printer_id = :pid +WHERE + id = :jid +; + +-- name: start-job! +UPDATE jobs +SET + started_at = datetime('now') +WHERE + id = :jid +; + +-- name: cancel-job! +UPDATE jobs +SET + cancelled_at = datetime('now') +WHERE + user_id = :uid + AND id = :jid +; + +-- name: finish-job! +UPDATE jobs +SET + finished_at = datetime('now') + , status_id = (SELECT id FROM job_statuses WHERE name = :state) + , message = :message +WHERE + id = :jid + AND finished_at IS NULL -- guard against calling this twice +; + +-- name: delete-job! +DELETE FROM jobs +WHERE + user_id = :uid + AND id = :jid +; diff --git a/projects/tentacles/src/python/tentacles/sql/migrations.sql b/projects/tentacles/src/python/tentacles/sql/migrations.sql new file mode 100644 index 0000000..055d16f --- /dev/null +++ b/projects/tentacles/src/python/tentacles/sql/migrations.sql @@ -0,0 +1,26 @@ +-- name: migration-0000-create-migrations# +CREATE TABLE IF NOT EXISTS migrations ( + id INTEGER PRIMARY KEY AUTOINCREMENT + , name TEXT + , fingerprint TEXT + , executed_at TEXT DEFAULT (datetime('now')) + , UNIQUE(name) +); + +-- name: list-migrations +SELECT + * +FROM migrations +ORDER BY + datetime(executed_at) ASC +; + +-- name: record-migration! +INSERT INTO migrations ( + name + , fingerprint +) +VALUES ( + :name + , :fingerprint +); diff --git a/projects/tentacles/src/python/tentacles/sql/printers.sql b/projects/tentacles/src/python/tentacles/sql/printers.sql new file mode 100644 index 0000000..478d63f --- /dev/null +++ b/projects/tentacles/src/python/tentacles/sql/printers.sql @@ -0,0 +1,165 @@ +-- name: migration-0000-create-printers# +CREATE TABLE IF NOT EXISTS printer_statuses ( + id INTEGER PRIMARY KEY AUTOINCREMENT + , name TEXT + , UNIQUE(name) +); + +INSERT OR IGNORE INTO printer_statuses (id, name) VALUES (-1, 'error'); +INSERT OR IGNORE INTO printer_statuses (id, name) VALUES (0, 'disconnected'); +INSERT OR IGNORE INTO printer_statuses (id, name) VALUES (2, 'connecting'); +INSERT OR IGNORE INTO printer_statuses (id, name) VALUES (2, 'connected'); +INSERT OR IGNORE INTO printer_statuses (id, name) VALUES (3, 'idle'); +INSERT OR IGNORE INTO printer_statuses (id, name) VALUES (4, 'running'); + +CREATE TABLE IF NOT EXISTS printers ( + id INTEGER PRIMARY KEY AUTOINCREMENT + , name TEXT + , url TEXT + , stream_url TEXT + , api_key TEXT + , status_id INTEGER + , last_poll_date TEXT + , FOREIGN KEY(status_id) REFERENCES printer_statuses(id) +); + +-- name: migration-0001-create-printer-occupied-state# +-- Create a state representing that the printer needs to be unloaded after a print +INSERT OR IGNORE INTO printer_statuses (id, name) VALUES (5, 'occupied'); + +-- name: migration-0002-create-printer-chassis# +CREATE TABLE IF NOT EXISTS printer_chassis ( + id INTEGER PRIMARY KEY AUTOINCREMENT + , name TEXT + , limit_x INTEGER + , limit_y INTEGER + , limit_z INTEGER + , limit_bed INTEGER + , limit_hotend INTEGER + , limit_tools INTEGER + , UNIQUE(name) +); + +INSERT INTO printer_chassis (name, limit_x, limit_y, limit_z, limit_bed, limit_hotend, limit_tools) VALUES ( + 'Creality CR-10v3', 300, 300, 400, 100, 260, 1 +); + +INSERT INTO printer_chassis (name, limit_x, limit_y, limit_z, limit_bed, limit_hotend, limit_tools) VALUES ( + 'Prusa Mini', 180, 180, 180, 100, 280, 1 +); + +INSERT INTO printer_chassis (name, limit_x, limit_y, limit_z, limit_bed, limit_hotend, limit_tools) VALUES ( + 'Prusa i3', 250, 210, 210, 120, 300, 1 +); + +INSERT INTO printer_chassis (name, limit_x, limit_y, limit_z, limit_bed, limit_hotend, limit_tools) VALUES ( + 'Prusa XL', 360, 360, 360, 120, 300, 5 +); + +ALTER TABLE printers ADD chassis_id INTEGER REFERENCES printer_chassis(id) DEFAULT 1; + +-- name: migration-0003-create-printer-filament# +CREATE TABLE IF NOT EXISTS filament ( + id INTEGER PRIMARY KEY AUTOINCREMENT + , name TEXT + , UNIQUE(name) +); + +INSERT OR IGNORE INTO filament (name) VALUES ('pla'); +INSERT OR IGNORE INTO filament (name) VALUES ('abs'); +INSERT OR IGNORE INTO filament (name) VALUES ('petg'); + +ALTER TABLE printers ADD filament_id INTEGER REFERENCES filament(id) DEFAULT 1; + + +-- name: migration-0004-create-printer-enabled# +ALTER TABLE printers ADD enabled BOOLEAN DEFAULT TRUE; + +-- name: migration-0005-create-printer-nozzle# +ALTER TABLE printers ADD nozzle_diameter INTEGER default 4; + +-- name: try-create-printer^ +INSERT INTO printers ( + name + , url + , api_key + , status_id +) +VALUES (:name, :url, :api_key, :sid) +RETURNING + id +; + +-- name: fetch-printer^ +SELECT + p.id + , p.name + , p.url + , p.stream_url + , p.api_key + , p.last_poll_date + , s.name as status +FROM printers p +INNER JOIN printer_statuses s ON p.status_id = s.id +WHERE p.id = :pid +; + +-- name: list-printers +SELECT + p.id + , p.name + , p.url + , p.stream_url + , p.api_key + , p.last_poll_date + , s.name as status +FROM printers p +INNER JOIN printer_statuses s ON p.status_id = s.id +; + +-- name: list-idle-printers +SELECT + p.id as id + , c.limit_x + , c.limit_y + , c.limit_z + , c.limit_hotend + , c.limit_bed + , c.limit_tools + , p.nozzle_diameter +FROM printers p +LEFT JOIN (SELECT id, printer_id FROM jobs WHERE finished_at IS NULL) j + ON p.id = j.printer_id +INNER JOIN printer_statuses s + ON p.status_id = s.id +INNER JOIN printer_chassis c + ON p.chassis_id = c.id +INNER JOIN filament f + ON p.filament_id = f.id +WHERE + j.id IS NULL + AND s.name = 'idle' + AND p.enabled = TRUE +; + +-- name: update-printer-status! +UPDATE printers +SET + status_id = (SELECT id FROM printer_statuses WHERE name = :status or id = :status) + , last_poll_date = datetime('now') +WHERE + id = :pid +; + +-- name: edit-printer +UPDATE printers +SET + name = :name + , url = :url + , stream_url = :stream_url + , api_key = :api_key + , filament_load = :filament_load + , enabled = (CASE WHEN LOWER(:enabled) = 'true' THEN 1 ELSE 0) +WHERE + id = :id +; diff --git a/projects/tentacles/src/python/tentacles/sql/user_keys.sql b/projects/tentacles/src/python/tentacles/sql/user_keys.sql new file mode 100644 index 0000000..ce70a17 --- /dev/null +++ b/projects/tentacles/src/python/tentacles/sql/user_keys.sql @@ -0,0 +1,92 @@ +-- name: migration-0000-create-user-keys# +-- Keys represent API keys and auth sessions +CREATE TABLE IF NOT EXISTS user_keys ( + id TEXT PRIMARY KEY DEFAULT (lower(hex(randomblob(32)))) + , user_id INTEGER + , name TEXT + , expiration TEXT +); + +-- name: create-key^ +INSERT INTO user_keys ( + user_id + , name + , expiration +) +VALUES (:uid, :name, :expiration) +RETURNING + id + , user_id +; + +-- name: try-login^ +SELECT + id + , status_id +FROM users +WHERE + ((name = :username AND hash = :hash) + OR (email = :username AND hash = :hash)) + AND ((verified_at IS NOT NULL + AND approved_at IS NOT NULL + AND enabled_at IS NOT NULL) + OR group_id = 0) +LIMIT 1 +; + +-- name: list-keys +SELECT + id + , name + , expiration +FROM user_keys +WHERE + user_id = :uid +; + +-- name: list-nonweb-keys +SELECT + id + , name + , expiration +FROM user_keys +WHERE + user_id = :uid + AND name NOT LIKE '%web session%' +; + +-- name: fetch-key^ +SELECT + * +FROM user_keys +WHERE + id = :kid +; + +-- name: try-key^ +SELECT + k.id + , user_id +FROM user_keys k +INNER JOIN users u + ON k.user_id = u.id +WHERE + (expiration IS NULL OR unixepoch(expiration) > unixepoch('now')) + AND k.id = :kid + AND u.enabled_at IS NOT NULL -- and the user is not disabled! +; + +-- name: refresh-key +UPDATE user_keys +SET + expiration = :expiration +WHERE + id = :kid +; + +-- name: delete-key +DELETE FROM user_keys +WHERE + user_id = :uid + AND id = :kid +; diff --git a/projects/tentacles/src/python/tentacles/sql/user_statuses.sql b/projects/tentacles/src/python/tentacles/sql/user_statuses.sql new file mode 100644 index 0000000..d184269 --- /dev/null +++ b/projects/tentacles/src/python/tentacles/sql/user_statuses.sql @@ -0,0 +1,8 @@ +-- name: fetch-user-status^ +SELECT + id + , name +FROM user_statuses +WHERE + id = :uid +; diff --git a/projects/tentacles/src/python/tentacles/sql/users.sql b/projects/tentacles/src/python/tentacles/sql/users.sql new file mode 100644 index 0000000..dab1464 --- /dev/null +++ b/projects/tentacles/src/python/tentacles/sql/users.sql @@ -0,0 +1,135 @@ +---------------------------------------------------------------------------------------------------- +-- Users, their statuses and groups +---------------------------------------------------------------------------------------------------- + +-- name: migration-0001-create-users# +CREATE TABLE IF NOT EXISTS groups ( + id INTEGER PRIMARY KEY AUTOINCREMENT + , name TEXT + , priority INTEGER CHECK(priority IS NOT NULL AND priority > 0) +); + +INSERT OR IGNORE INTO groups (id, name, priority) VALUES (0, 'root', 20); +INSERT OR IGNORE INTO groups (id, name, priority) VALUES (1, 'users', 10); +INSERT OR IGNORE INTO groups (id, name, priority) VALUES (2, 'guests', 0); + +CREATE TABLE IF NOT EXISTS user_statuses ( + id INTEGER PRIMARY KEY AUTOINCREMENT + , name TEXT + , UNIQUE(name) +); + +INSERT OR IGNORE INTO user_statuses (id, name) VALUES (-4, 'passwdchng'); +INSERT OR IGNORE INTO user_statuses (id, name) VALUES (-3, 'unverified'); +INSERT OR IGNORE INTO user_statuses (id, name) VALUES (-2, 'unapproved'); +INSERT OR IGNORE INTO user_statuses (id, name) VALUES (-1, 'disabled'); +INSERT OR IGNORE INTO user_statuses (id, name) VALUES (1, 'enabled'); + +CREATE TABLE IF NOT EXISTS users ( + id INTEGER PRIMARY KEY AUTOINCREMENT + , group_id INTEGER + , name TEXT + , email TEXT + , hash TEXT + , status_id INTEGER + , created_at TEXT DEFAULT (datetime('now')) + , verification_token TEXT DEFAULT (lower(hex(randomblob(32)))) + , verified_at TEXT + , approved_at TEXT + , enabled_at TEXT + , FOREIGN KEY(group_id) REFERENCES groups(id) + , FOREIGN KEY(status_id) REFERENCES user_statuses(id) + , UNIQUE(name) + , UNIQUE(email) +); + +-- name: try-create-user^ +INSERT INTO users ( + name + , email + , hash + , group_id + , status_id +) +VALUES (:name, :email, :hash, :gid, :sid) +RETURNING * +; + +-- name: fetch_user^ +SELECT + * +FROM users +WHERE + id = :uid +; + +-- name: list-users +SELECT + * +FROM users +; + +-- name: list-unverified-users +SELECT + * +FROM users +WHERE + status_id = -2 + AND verified_at IS NULL +; + +-- name: try-verify-user^ +UPDATE users +SET + verified_at = datetime('now') + , verification_token = lower(hex(randomblob(32))) +WHERE + verification_token = :token +RETURNING + id + , name +; + +-- name: enable-user^ +UPDATE users +SET + enabled_at = datetime('now') +WHERE + id = :uid +RETURNING + id + , name +; + +-- name: disable-user^ +UPDATE users +SET + enabled_at = NULL +WHERE + id = :uid +RETURNING + id + , name +; + +-- name: approve-user^ +UPDATE users +SET + approved_at = datetime('now') +WHERE + id = :uid +RETURNING + id + , name +; + +-- name: set-user-status^ +UPDATE users +SET + status_id = (SELECT id FROM user_statuses WHERE id = :status OR name = :status) +WHERE + id = :uid +RETURNING + id + , name +; diff --git a/projects/tentacles/src/python/tentacles/workers.py b/projects/tentacles/src/python/tentacles/workers.py index 90f599f..956cc5d 100644 --- a/projects/tentacles/src/python/tentacles/workers.py +++ b/projects/tentacles/src/python/tentacles/workers.py @@ -81,7 +81,7 @@ def poll_printers(app: App, db: Db) -> None: "/api/plugin/bedready", json={ "command": "check_bed", - "similarity": 0.97, + "similarity": 0.94, "reference": snapshots[0], }, ) @@ -290,6 +290,14 @@ def send_emails(app, db: Db): db.send_email(eid=message.id) +def debug_queue(app: App, db: Db): + output = ["---"] + for job in db.list_running_jobs(): + output.append(repr(job)) + for printer in db.list_idle_printers(): + output.append(repr(printer)) + print("\n".join(output)) + def toil(*fs): def _helper(*args, **kwargs): for f in fs: