From d03a76db234ea92bd411a01323ae68648d1acb9e Mon Sep 17 00:00:00 2001 From: "Schimon Jehudah, Adv." Date: Sun, 17 Nov 2024 16:24:16 +0200 Subject: [PATCH] SQLite: Add an SQL script to generate the SQLite database; CSS : Remove property height from element ID 'related-tags'. --- blasta.sql | 310 ++++++++++++++++ blasta/__main__.py | 10 +- blasta/assets/stylesheet/stylesheet.css | 2 +- blasta/database/sqlite.py | 459 +----------------------- 4 files changed, 326 insertions(+), 455 deletions(-) create mode 100644 blasta.sql diff --git a/blasta.sql b/blasta.sql new file mode 100644 index 0000000..8b37936 --- /dev/null +++ b/blasta.sql @@ -0,0 +1,310 @@ +-- Blasta SQLite database script. + +CREATE TABLE IF NOT EXISTS main_entries ( + id INTEGER NOT NULL, + url_hash TEXT NOT NULL UNIQUE, + url TEXT NOT NULL UNIQUE, + title TEXT NOT NULL, + summary TEXT, + jid_id TEXT NOT NULL, + date_first TEXT NOT NULL, + date_last TEXT NOT NULL, + instances INTEGER NOT NULL DEFAULT 1, + PRIMARY KEY ("id") + ); + +CREATE TABLE IF NOT EXISTS main_jids ( + id INTEGER NOT NULL, + jid TEXT NOT NULL UNIQUE, + opt_in INTEGER NOT NULL DEFAULT 0, + PRIMARY KEY ("id") + ); + +CREATE TABLE IF NOT EXISTS main_tags ( + id INTEGER NOT NULL, + tag TEXT NOT NULL UNIQUE, + instances INTEGER NOT NULL DEFAULT 1, + PRIMARY KEY ("id") + ); + +CREATE TABLE IF NOT EXISTS main_statistics ( + id INTEGER NOT NULL, + type TEXT NOT NULL UNIQUE, + count INTEGER NOT NULL DEFAULT 0, + PRIMARY KEY ("id") + ); + +INSERT +INTO main_statistics( + type) +VALUES ('entries'), + ('jids'), + ('tags'); + +CREATE TABLE IF NOT EXISTS combination_entries_tags_jids ( + id INTEGER NOT NULL, + entry_id INTEGER NOT NULL, + tag_id INTEGER NOT NULL, + jid_id INTEGER NOT NULL, + FOREIGN KEY ("entry_id") REFERENCES "main_entries" ("id") + ON UPDATE CASCADE + ON DELETE CASCADE, + FOREIGN KEY ("tag_id") REFERENCES "main_tags" ("id") + ON UPDATE CASCADE + ON DELETE CASCADE, + FOREIGN KEY ("jid_id") REFERENCES "main_jids" ("id") + ON UPDATE CASCADE + ON DELETE CASCADE, + PRIMARY KEY ("id") + ); + +-- NOTE Digit for JID which is authorized; +-- Zero (0) for private; +-- Empty (no row) for public. + +CREATE TABLE IF NOT EXISTS authorization_entries_jids ( + id INTEGER NOT NULL, + entry_id INTEGER NOT NULL, + jid_id INTEGER NOT NULL, + authorization INTEGER NOT NULL, + FOREIGN KEY ("entry_id") REFERENCES "main_entries" ("id") + ON UPDATE CASCADE + ON DELETE CASCADE, + FOREIGN KEY ("jid_id") REFERENCES "main_jids" ("id") + ON UPDATE CASCADE + ON DELETE CASCADE, + PRIMARY KEY ("id") + ); + +CREATE TABLE IF NOT EXISTS report_entries ( + id INTEGER NOT NULL, + url_hash_subject TEXT NOT NULL, + jid_reporter TEXT NOT NULL, + type TEXT, + comment TEXT, + PRIMARY KEY ("id") + ); + +CREATE TABLE IF NOT EXISTS report_jids ( + id INTEGER NOT NULL, + jid_subject TEXT NOT NULL, + jid_reporter TEXT NOT NULL, + type TEXT, + comment TEXT, + PRIMARY KEY ("id") + ); + +CREATE TRIGGER instances_entry_decrease +AFTER DELETE ON combination_entries_tags_jids +FOR EACH ROW +BEGIN + UPDATE main_entries + SET instances = ( + SELECT COUNT(DISTINCT jid_id) + FROM combination_entries_tags_jids + WHERE entry_id = OLD.entry_id + ) + WHERE id = OLD.entry_id; +END; + +CREATE TRIGGER instances_entry_increase +AFTER INSERT ON combination_entries_tags_jids +FOR EACH ROW +BEGIN + UPDATE main_entries + SET instances = ( + SELECT COUNT(DISTINCT jid_id) + FROM combination_entries_tags_jids + WHERE entry_id = NEW.entry_id + ) + WHERE id = NEW.entry_id; +END; + +CREATE TRIGGER instances_entry_update +AFTER UPDATE ON combination_entries_tags_jids +FOR EACH ROW +BEGIN + -- Decrease instances for the old tag_id + UPDATE main_entries + SET instances = ( + SELECT COUNT(DISTINCT jid_id) + FROM combination_entries_tags_jids + WHERE entry_id = OLD.entry_id + ) + WHERE id = OLD.entry_id; + + -- Increase instances for the new tag_id + UPDATE main_entries + SET instances = ( + SELECT COUNT(DISTINCT jid_id) + FROM combination_entries_tags_jids + WHERE entry_id = NEW.entry_id + ) + WHERE id = NEW.entry_id; +END; + + +CREATE TRIGGER instances_tag_decrease +AFTER DELETE ON combination_entries_tags_jids +FOR EACH ROW +BEGIN + UPDATE main_tags + SET instances = ( + SELECT COUNT(*) + FROM combination_entries_tags_jids + WHERE tag_id = OLD.tag_id + ) + WHERE id = OLD.tag_id; +END; + +CREATE TRIGGER instances_tag_increase +AFTER INSERT ON combination_entries_tags_jids +FOR EACH ROW +BEGIN + UPDATE main_tags + SET instances = ( + SELECT COUNT(*) + FROM combination_entries_tags_jids + WHERE tag_id = NEW.tag_id + ) + WHERE id = NEW.tag_id; +END; + +CREATE TRIGGER instances_tag_update +AFTER UPDATE ON combination_entries_tags_jids +FOR EACH ROW +BEGIN + -- Decrease instances for the old tag_id + UPDATE main_tags + SET instances = ( + SELECT COUNT(*) + FROM combination_entries_tags_jids + WHERE tag_id = OLD.tag_id + ) + WHERE id = OLD.tag_id; + + -- Increase instances for the new tag_id + UPDATE main_tags + SET instances = ( + SELECT COUNT(*) + FROM combination_entries_tags_jids + WHERE tag_id = NEW.tag_id + ) + WHERE id = NEW.tag_id; +END; + +CREATE TRIGGER entry_count_increase +AFTER INSERT ON main_entries +BEGIN + UPDATE main_statistics + SET count = ( + SELECT COUNT(*) + FROM main_entries + ) + WHERE type = 'entries'; +END; + + +CREATE TRIGGER entry_count_decrease +AFTER DELETE ON main_entries +BEGIN + UPDATE main_statistics + SET count = ( + SELECT COUNT(*) + FROM main_entries + ) + WHERE type = 'entries'; +END; + +CREATE TRIGGER entry_count_update +AFTER UPDATE ON main_entries +BEGIN + UPDATE main_statistics + SET count = ( + SELECT COUNT(*) + FROM main_entries + ) + WHERE type = 'entries'; +END; + +CREATE TRIGGER entry_remove +AFTER UPDATE ON main_entries +FOR EACH ROW +WHEN NEW.instances < 1 +BEGIN + DELETE FROM main_entries WHERE id = OLD.id; +END; + +CREATE TRIGGER jid_count_increase +AFTER INSERT ON main_jids +BEGIN + UPDATE main_statistics + SET count = ( + SELECT COUNT(*) + FROM main_jids + ) + WHERE type = 'jids'; +END; + +CREATE TRIGGER jid_count_decrease +AFTER DELETE ON main_jids +BEGIN + UPDATE main_statistics + SET count = ( + SELECT COUNT(*) + FROM main_jids + ) + WHERE type = 'jids'; +END; + +CREATE TRIGGER jid_count_update +AFTER UPDATE ON main_jids +BEGIN + UPDATE main_statistics + SET count = ( + SELECT COUNT(*) + FROM main_jids + ) + WHERE type = 'jids'; +END; + +CREATE TRIGGER tag_count_increase +AFTER INSERT ON main_tags +BEGIN + UPDATE main_statistics + SET count = ( + SELECT COUNT(*) + FROM main_tags + ) + WHERE type = 'tags'; +END; + +CREATE TRIGGER tag_count_decrease +AFTER DELETE ON main_tags +BEGIN + UPDATE main_statistics + SET count = ( + SELECT COUNT(*) + FROM main_tags + ) + WHERE type = 'tags'; +END; + +CREATE TRIGGER tag_count_update +AFTER UPDATE ON main_tags +BEGIN + UPDATE main_statistics + SET count = ( + SELECT COUNT(*) + FROM main_tags + ) + WHERE type = 'tags'; +END; + +CREATE TRIGGER tag_remove +AFTER UPDATE ON main_tags +FOR EACH ROW +WHEN NEW.instances < 1 +BEGIN + DELETE FROM main_tags WHERE id = OLD.id; +END; diff --git a/blasta/__main__.py b/blasta/__main__.py index 3408c4f..ae2d9dc 100644 --- a/blasta/__main__.py +++ b/blasta/__main__.py @@ -12,7 +12,7 @@ TODO """ import argparse -from blasta.config import Share +from blasta.config import Settings, Share from blasta.http.instance import HttpInstance from blasta.database.sqlite import DatabaseSQLite import json @@ -34,10 +34,12 @@ except: def main(): + directory_config = Settings.get_directory() + sql_filename = os.path.join(directory_config, 'blasta.sql') directory_data = Share.get_directory() - db_file = os.path.join(directory_data, 'main.sqlite') - if not exists(db_file) or not getsize(db_file): - DatabaseSQLite.instantiate_database(db_file) + dbs_filename = os.path.join(directory_data, 'main.sqlite') + if not exists(dbs_filename) or not getsize(dbs_filename): + DatabaseSQLite.create_tables(sql_filename, dbs_filename) accounts = {} sessions = {} http_instance = HttpInstance(accounts, sessions) diff --git a/blasta/assets/stylesheet/stylesheet.css b/blasta/assets/stylesheet/stylesheet.css index e6caac7..067a2d6 100644 --- a/blasta/assets/stylesheet/stylesheet.css +++ b/blasta/assets/stylesheet/stylesheet.css @@ -161,9 +161,9 @@ form > * { #related-tags { background-color: #eee; + /* height: 90vh; */ min-width: 200px; padding: 0 0.5em 1em 1em; - height: 90vh; width: 15%; /* float: right; */ /* width: 200px; */ diff --git a/blasta/database/sqlite.py b/blasta/database/sqlite.py index 4d2233c..8d8ac89 100644 --- a/blasta/database/sqlite.py +++ b/blasta/database/sqlite.py @@ -10,17 +10,6 @@ DBLOCK = Lock() class DatabaseSQLite: - def instantiate_database(db_file): -# db_dir = get_default_data_directory() -# if not os.path.isdir(db_dir): -# os.mkdir(db_dir) -# if not os.path.isdir(db_dir + "/sqlite"): -# os.mkdir(db_dir + "/sqlite") -# db_file = os.path.join(db_dir, "sqlite", r"{}.db".format(jid_file)) - DatabaseSQLite.create_tables(db_file) - DatabaseSQLite.add_statistics(db_file) - return db_file - #from slixfeed.log import Logger #from slixfeed.utilities import DateAndTime, Url @@ -63,7 +52,7 @@ class DatabaseSQLite: return conn - def create_tables(db_file): + def create_tables(sql_filename, db_file): """ Create SQLite tables. @@ -76,446 +65,16 @@ class DatabaseSQLite: # logger.debug('{}: db_file: {}' # .format(function_name, db_file)) with DatabaseSQLite.create_connection(db_file) as conn: - sql_table_main_entries = ( - """ - CREATE TABLE IF NOT EXISTS main_entries ( - id INTEGER NOT NULL, - url_hash TEXT NOT NULL UNIQUE, - url TEXT NOT NULL UNIQUE, - title TEXT NOT NULL, - summary TEXT, - jid_id TEXT NOT NULL, - date_first TEXT NOT NULL, - date_last TEXT NOT NULL, - instances INTEGER NOT NULL DEFAULT 1, - PRIMARY KEY ("id") - ); - """ - ) - sql_table_main_jids = ( - """ - CREATE TABLE IF NOT EXISTS main_jids ( - id INTEGER NOT NULL, - jid TEXT NOT NULL UNIQUE, - opt_in INTEGER NOT NULL DEFAULT 0, - PRIMARY KEY ("id") - ); - """ - ) - sql_table_main_tags = ( - """ - CREATE TABLE IF NOT EXISTS main_tags ( - id INTEGER NOT NULL, - tag TEXT NOT NULL UNIQUE, - instances INTEGER NOT NULL DEFAULT 1, - PRIMARY KEY ("id") - ); - """ - ) - sql_table_main_statistics = ( - """ - CREATE TABLE IF NOT EXISTS main_statistics ( - id INTEGER NOT NULL, - type TEXT NOT NULL UNIQUE, - count INTEGER NOT NULL DEFAULT 0, - PRIMARY KEY ("id") - ); - """ - ) - sql_table_combination_entries_tags_jids = ( - """ - CREATE TABLE IF NOT EXISTS combination_entries_tags_jids ( - id INTEGER NOT NULL, - entry_id INTEGER NOT NULL, - tag_id INTEGER NOT NULL, - jid_id INTEGER NOT NULL, - FOREIGN KEY ("entry_id") REFERENCES "main_entries" ("id") - ON UPDATE CASCADE - ON DELETE CASCADE, - FOREIGN KEY ("tag_id") REFERENCES "main_tags" ("id") - ON UPDATE CASCADE - ON DELETE CASCADE, - FOREIGN KEY ("jid_id") REFERENCES "main_jids" ("id") - ON UPDATE CASCADE - ON DELETE CASCADE, - PRIMARY KEY ("id") - ); - """ - ) - # NOTE Digit for JID which is authorized; - # Zero (0) for private; - # Empty (no row) for public. - sql_table_authorization_entries_jids = ( - """ - CREATE TABLE IF NOT EXISTS authorization_entries_jids ( - id INTEGER NOT NULL, - entry_id INTEGER NOT NULL, - jid_id INTEGER NOT NULL, - authorization INTEGER NOT NULL, - FOREIGN KEY ("entry_id") REFERENCES "main_entries" ("id") - ON UPDATE CASCADE - ON DELETE CASCADE, - FOREIGN KEY ("jid_id") REFERENCES "main_jids" ("id") - ON UPDATE CASCADE - ON DELETE CASCADE, - PRIMARY KEY ("id") - ); - """ - ) - sql_table_report_entries = ( - """ - CREATE TABLE IF NOT EXISTS report_entries ( - id INTEGER NOT NULL, - url_hash_subject TEXT NOT NULL, - jid_reporter TEXT NOT NULL, - type TEXT, - comment TEXT, - PRIMARY KEY ("id") - ); - """ - ) - sql_table_report_jids = ( - """ - CREATE TABLE IF NOT EXISTS report_jids ( - id INTEGER NOT NULL, - jid_subject TEXT NOT NULL, - jid_reporter TEXT NOT NULL, - type TEXT, - comment TEXT, - PRIMARY KEY ("id") - ); - """ - ) - sql_trigger_instances_entry_decrease = ( - """ - CREATE TRIGGER instances_entry_decrease - AFTER DELETE ON combination_entries_tags_jids - FOR EACH ROW - BEGIN - UPDATE main_entries - SET instances = ( - SELECT COUNT(DISTINCT jid_id) - FROM combination_entries_tags_jids - WHERE entry_id = OLD.entry_id - ) - WHERE id = OLD.entry_id; - END; - """ - ) - sql_trigger_instances_entry_increase = ( - """ - CREATE TRIGGER instances_entry_increase - AFTER INSERT ON combination_entries_tags_jids - FOR EACH ROW - BEGIN - UPDATE main_entries - SET instances = ( - SELECT COUNT(DISTINCT jid_id) - FROM combination_entries_tags_jids - WHERE entry_id = NEW.entry_id - ) - WHERE id = NEW.entry_id; - END; - """ - ) - sql_trigger_instances_entry_update = ( - """ - CREATE TRIGGER instances_entry_update - AFTER UPDATE ON combination_entries_tags_jids - FOR EACH ROW - BEGIN - -- Decrease instances for the old tag_id - UPDATE main_entries - SET instances = ( - SELECT COUNT(DISTINCT jid_id) - FROM combination_entries_tags_jids - WHERE entry_id = OLD.entry_id - ) - WHERE id = OLD.entry_id; - - -- Increase instances for the new tag_id - UPDATE main_entries - SET instances = ( - SELECT COUNT(DISTINCT jid_id) - FROM combination_entries_tags_jids - WHERE entry_id = NEW.entry_id - ) - WHERE id = NEW.entry_id; - END; - """ - ) - sql_trigger_instances_tag_decrease = ( - """ - CREATE TRIGGER instances_tag_decrease - AFTER DELETE ON combination_entries_tags_jids - FOR EACH ROW - BEGIN - UPDATE main_tags - SET instances = ( - SELECT COUNT(*) - FROM combination_entries_tags_jids - WHERE tag_id = OLD.tag_id - ) - WHERE id = OLD.tag_id; - END; - """ - ) - sql_trigger_instances_tag_increase = ( - """ - CREATE TRIGGER instances_tag_increase - AFTER INSERT ON combination_entries_tags_jids - FOR EACH ROW - BEGIN - UPDATE main_tags - SET instances = ( - SELECT COUNT(*) - FROM combination_entries_tags_jids - WHERE tag_id = NEW.tag_id - ) - WHERE id = NEW.tag_id; - END; - """ - ) - sql_trigger_instances_tag_update = ( - """ - CREATE TRIGGER instances_tag_update - AFTER UPDATE ON combination_entries_tags_jids - FOR EACH ROW - BEGIN - -- Decrease instances for the old tag_id - UPDATE main_tags - SET instances = ( - SELECT COUNT(*) - FROM combination_entries_tags_jids - WHERE tag_id = OLD.tag_id - ) - WHERE id = OLD.tag_id; - - -- Increase instances for the new tag_id - UPDATE main_tags - SET instances = ( - SELECT COUNT(*) - FROM combination_entries_tags_jids - WHERE tag_id = NEW.tag_id - ) - WHERE id = NEW.tag_id; - END; - """ - ) - sql_trigger_entry_count_increase = ( - """ - CREATE TRIGGER entry_count_increase - AFTER INSERT ON main_entries - BEGIN - UPDATE main_statistics - SET count = ( - SELECT COUNT(*) - FROM main_entries - ) - WHERE type = 'entries'; - END; - """ - ) - sql_trigger_entry_count_decrease = ( - """ - CREATE TRIGGER entry_count_decrease - AFTER DELETE ON main_entries - BEGIN - UPDATE main_statistics - SET count = ( - SELECT COUNT(*) - FROM main_entries - ) - WHERE type = 'entries'; - END; - """ - ) - sql_trigger_entry_count_update = ( - """ - CREATE TRIGGER entry_count_update - AFTER UPDATE ON main_entries - BEGIN - UPDATE main_statistics - SET count = ( - SELECT COUNT(*) - FROM main_entries - ) - WHERE type = 'entries'; - END; - """ - ) - sql_trigger_entry_remove = ( - """ - CREATE TRIGGER entry_remove - AFTER UPDATE ON main_entries - FOR EACH ROW - WHEN NEW.instances < 1 - BEGIN - DELETE FROM main_entries WHERE id = OLD.id; - END; - """ - ) - sql_trigger_jid_count_increase = ( - """ - CREATE TRIGGER jid_count_increase - AFTER INSERT ON main_jids - BEGIN - UPDATE main_statistics - SET count = ( - SELECT COUNT(*) - FROM main_jids - ) - WHERE type = 'jids'; - END; - """ - ) - sql_trigger_jid_count_decrease = ( - """ - CREATE TRIGGER jid_count_decrease - AFTER DELETE ON main_jids - BEGIN - UPDATE main_statistics - SET count = ( - SELECT COUNT(*) - FROM main_jids - ) - WHERE type = 'jids'; - END; - """ - ) - sql_trigger_jid_count_update = ( - """ - CREATE TRIGGER jid_count_update - AFTER UPDATE ON main_jids - BEGIN - UPDATE main_statistics - SET count = ( - SELECT COUNT(*) - FROM main_jids - ) - WHERE type = 'jids'; - END; - """ - ) - sql_trigger_tag_count_increase = ( - """ - CREATE TRIGGER tag_count_increase - AFTER INSERT ON main_tags - BEGIN - UPDATE main_statistics - SET count = ( - SELECT COUNT(*) - FROM main_tags - ) - WHERE type = 'tags'; - END; - """ - ) - sql_trigger_tag_count_decrease = ( - """ - CREATE TRIGGER tag_count_decrease - AFTER DELETE ON main_tags - BEGIN - UPDATE main_statistics - SET count = ( - SELECT COUNT(*) - FROM main_tags - ) - WHERE type = 'tags'; - END; - """ - ) - sql_trigger_tag_count_update = ( - """ - CREATE TRIGGER tag_count_update - AFTER UPDATE ON main_tags - BEGIN - UPDATE main_statistics - SET count = ( - SELECT COUNT(*) - FROM main_tags - ) - WHERE type = 'tags'; - END; - """ - ) - sql_trigger_tag_remove = ( - """ - CREATE TRIGGER tag_remove - AFTER UPDATE ON main_tags - FOR EACH ROW - WHEN NEW.instances < 1 - BEGIN - DELETE FROM main_tags WHERE id = OLD.id; - END; - """ - ) - cur = conn.cursor() - cur.execute(sql_table_main_entries) - cur.execute(sql_table_main_jids) - cur.execute(sql_table_main_tags) - cur.execute(sql_table_main_statistics) - cur.execute(sql_table_combination_entries_tags_jids) - cur.execute(sql_table_authorization_entries_jids) - cur.execute(sql_table_report_entries) - cur.execute(sql_table_report_jids) - cur.execute(sql_trigger_instances_entry_decrease) - cur.execute(sql_trigger_instances_entry_increase) - cur.execute(sql_trigger_instances_entry_update) - cur.execute(sql_trigger_instances_tag_decrease) - cur.execute(sql_trigger_instances_tag_increase) - cur.execute(sql_trigger_instances_tag_update) - cur.execute(sql_trigger_entry_count_increase) - cur.execute(sql_trigger_entry_count_decrease) - cur.execute(sql_trigger_entry_count_update) - cur.execute(sql_trigger_entry_remove) - cur.execute(sql_trigger_jid_count_increase) - cur.execute(sql_trigger_jid_count_decrease) - cur.execute(sql_trigger_jid_count_update) - cur.execute(sql_trigger_tag_count_increase) - cur.execute(sql_trigger_tag_count_decrease) - cur.execute(sql_trigger_tag_count_update) - cur.execute(sql_trigger_tag_remove) - - def add_statistics(db_file): - """ - Batch insertion of tags. - - Parameters - ---------- - db_file : str - Path to database file. - entries : list - Set of entries. - - Returns - ------- - None. - - Note - ---- - This function is executed immediately after the creation of the database - and, therefore, the directive "async with DBLOCK:" is not necessary. - """ - function_name = sys._getframe().f_code.co_name -# logger.debug('{}: db_file: {}' -# .format(function_name, db_file)) - sql = ( - """ - INSERT - INTO main_statistics( - type) - VALUES ('entries'), - ('jids'), - ('tags'); - """ - ) - with DatabaseSQLite.create_connection(db_file) as conn: + # Read the SQL script from the file + with open(sql_filename, 'r') as sql_file: + sql_script = sql_file.read() cur = conn.cursor() + # Execute the SQL script try: - cur.execute(sql) - except IntegrityError as e: - print(e) + cur.executescript(sql_script) + print("Table created successfully.") + except sqlite3.Error as e: + print(f"An error occurred: {e}") async def associate_entries_tags_jids(db_file, entry): async with DBLOCK: